Doc: fix bogus to_date() examples.
[pgsql.git] / doc / src / sgml / func.sgml
blob8656bf3ab5713f539f25cf322b50a9ccdcc4ba5a
1 <!-- doc/src/sgml/func.sgml -->
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. This chapter
17 describes most of them, although additional special-purpose functions
18 appear in relevant sections of the manual. Users can also
19 define their own functions and operators, as described in
20 <xref linkend="server-programming"/>. The
21 <application>psql</application> commands <command>\df</command> and
22 <command>\do</command> can be used to list all
23 available functions and operators, respectively.
24 </para>
26 <para>
27 The notation used throughout this chapter to describe the argument and
28 result data types of a function or operator is like this:
29 <synopsis>
30 <function>repeat</function> ( <type>text</type>, <type>integer</type> ) <returnvalue>text</returnvalue>
31 </synopsis>
32 which says that the function <function>repeat</function> takes one text and
33 one integer argument and returns a result of type text. The right arrow
34 is also used to indicate the result of an example, thus:
35 <programlisting>
36 repeat('Pg', 4) <returnvalue>PgPgPgPg</returnvalue>
37 </programlisting>
38 </para>
40 <para>
41 If you are concerned about portability then note that most of
42 the functions and operators described in this chapter, with the
43 exception of the most trivial arithmetic and comparison operators
44 and some explicitly marked functions, are not specified by the
45 <acronym>SQL</acronym> standard. Some of this extended functionality
46 is present in other <acronym>SQL</acronym> database management
47 systems, and in many cases this functionality is compatible and
48 consistent between the various implementations.
49 </para>
52 <sect1 id="functions-logical">
53 <title>Logical Operators</title>
55 <indexterm zone="functions-logical">
56 <primary>operator</primary>
57 <secondary>logical</secondary>
58 </indexterm>
60 <indexterm>
61 <primary>Boolean</primary>
62 <secondary>operators</secondary>
63 <see>operators, logical</see>
64 </indexterm>
66 <para>
67 The usual logical operators are available:
69 <indexterm>
70 <primary>AND (operator)</primary>
71 </indexterm>
73 <indexterm>
74 <primary>OR (operator)</primary>
75 </indexterm>
77 <indexterm>
78 <primary>NOT (operator)</primary>
79 </indexterm>
81 <indexterm>
82 <primary>conjunction</primary>
83 </indexterm>
85 <indexterm>
86 <primary>disjunction</primary>
87 </indexterm>
89 <indexterm>
90 <primary>negation</primary>
91 </indexterm>
93 <synopsis>
94 <type>boolean</type> <literal>AND</literal> <type>boolean</type> <returnvalue>boolean</returnvalue>
95 <type>boolean</type> <literal>OR</literal> <type>boolean</type> <returnvalue>boolean</returnvalue>
96 <literal>NOT</literal> <type>boolean</type> <returnvalue>boolean</returnvalue>
97 </synopsis>
99 <acronym>SQL</acronym> uses a three-valued logic system with true,
100 false, and <literal>null</literal>, which represents <quote>unknown</quote>.
101 Observe the following truth tables:
103 <informaltable>
104 <tgroup cols="4">
105 <thead>
106 <row>
107 <entry><replaceable>a</replaceable></entry>
108 <entry><replaceable>b</replaceable></entry>
109 <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
110 <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
111 </row>
112 </thead>
114 <tbody>
115 <row>
116 <entry>TRUE</entry>
117 <entry>TRUE</entry>
118 <entry>TRUE</entry>
119 <entry>TRUE</entry>
120 </row>
122 <row>
123 <entry>TRUE</entry>
124 <entry>FALSE</entry>
125 <entry>FALSE</entry>
126 <entry>TRUE</entry>
127 </row>
129 <row>
130 <entry>TRUE</entry>
131 <entry>NULL</entry>
132 <entry>NULL</entry>
133 <entry>TRUE</entry>
134 </row>
136 <row>
137 <entry>FALSE</entry>
138 <entry>FALSE</entry>
139 <entry>FALSE</entry>
140 <entry>FALSE</entry>
141 </row>
143 <row>
144 <entry>FALSE</entry>
145 <entry>NULL</entry>
146 <entry>FALSE</entry>
147 <entry>NULL</entry>
148 </row>
150 <row>
151 <entry>NULL</entry>
152 <entry>NULL</entry>
153 <entry>NULL</entry>
154 <entry>NULL</entry>
155 </row>
156 </tbody>
157 </tgroup>
158 </informaltable>
160 <informaltable>
161 <tgroup cols="2">
162 <thead>
163 <row>
164 <entry><replaceable>a</replaceable></entry>
165 <entry>NOT <replaceable>a</replaceable></entry>
166 </row>
167 </thead>
169 <tbody>
170 <row>
171 <entry>TRUE</entry>
172 <entry>FALSE</entry>
173 </row>
175 <row>
176 <entry>FALSE</entry>
177 <entry>TRUE</entry>
178 </row>
180 <row>
181 <entry>NULL</entry>
182 <entry>NULL</entry>
183 </row>
184 </tbody>
185 </tgroup>
186 </informaltable>
187 </para>
189 <para>
190 The operators <literal>AND</literal> and <literal>OR</literal> are
191 commutative, that is, you can switch the left and right operands
192 without affecting the result. (However, it is not guaranteed that
193 the left operand is evaluated before the right operand. See <xref
194 linkend="syntax-express-eval"/> for more information about the
195 order of evaluation of subexpressions.)
196 </para>
197 </sect1>
199 <sect1 id="functions-comparison">
200 <title>Comparison Functions and Operators</title>
202 <indexterm zone="functions-comparison">
203 <primary>comparison</primary>
204 <secondary>operators</secondary>
205 </indexterm>
207 <para>
208 The usual comparison operators are available, as shown in <xref
209 linkend="functions-comparison-op-table"/>.
210 </para>
212 <table id="functions-comparison-op-table">
213 <title>Comparison Operators</title>
214 <tgroup cols="2">
215 <thead>
216 <row>
217 <entry>Operator</entry>
218 <entry>Description</entry>
219 </row>
220 </thead>
222 <tbody>
223 <row>
224 <entry>
225 <replaceable>datatype</replaceable> <literal>&lt;</literal> <replaceable>datatype</replaceable>
226 <returnvalue>boolean</returnvalue>
227 </entry>
228 <entry>Less than</entry>
229 </row>
231 <row>
232 <entry>
233 <replaceable>datatype</replaceable> <literal>&gt;</literal> <replaceable>datatype</replaceable>
234 <returnvalue>boolean</returnvalue>
235 </entry>
236 <entry>Greater than</entry>
237 </row>
239 <row>
240 <entry>
241 <replaceable>datatype</replaceable> <literal>&lt;=</literal> <replaceable>datatype</replaceable>
242 <returnvalue>boolean</returnvalue>
243 </entry>
244 <entry>Less than or equal to</entry>
245 </row>
247 <row>
248 <entry>
249 <replaceable>datatype</replaceable> <literal>&gt;=</literal> <replaceable>datatype</replaceable>
250 <returnvalue>boolean</returnvalue>
251 </entry>
252 <entry>Greater than or equal to</entry>
253 </row>
255 <row>
256 <entry>
257 <replaceable>datatype</replaceable> <literal>=</literal> <replaceable>datatype</replaceable>
258 <returnvalue>boolean</returnvalue>
259 </entry>
260 <entry>Equal</entry>
261 </row>
263 <row>
264 <entry>
265 <replaceable>datatype</replaceable> <literal>&lt;&gt;</literal> <replaceable>datatype</replaceable>
266 <returnvalue>boolean</returnvalue>
267 </entry>
268 <entry>Not equal</entry>
269 </row>
271 <row>
272 <entry>
273 <replaceable>datatype</replaceable> <literal>!=</literal> <replaceable>datatype</replaceable>
274 <returnvalue>boolean</returnvalue>
275 </entry>
276 <entry>Not equal</entry>
277 </row>
278 </tbody>
279 </tgroup>
280 </table>
282 <note>
283 <para>
284 <literal>&lt;&gt;</literal> is the standard SQL notation for <quote>not
285 equal</quote>. <literal>!=</literal> is an alias, which is converted
286 to <literal>&lt;&gt;</literal> at a very early stage of parsing.
287 Hence, it is not possible to implement <literal>!=</literal>
288 and <literal>&lt;&gt;</literal> operators that do different things.
289 </para>
290 </note>
292 <para>
293 These comparison operators are available for all built-in data types
294 that have a natural ordering, including numeric, string, and date/time
295 types. In addition, arrays, composite types, and ranges can be compared
296 if their component data types are comparable.
297 </para>
299 <para>
300 It is usually possible to compare values of related data
301 types as well; for example <type>integer</type> <literal>&gt;</literal>
302 <type>bigint</type> will work. Some cases of this sort are implemented
303 directly by <quote>cross-type</quote> comparison operators, but if no
304 such operator is available, the parser will coerce the less-general type
305 to the more-general type and apply the latter's comparison operator.
306 </para>
308 <para>
309 As shown above, all comparison operators are binary operators that
310 return values of type <type>boolean</type>. Thus, expressions like
311 <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
312 no <literal>&lt;</literal> operator to compare a Boolean value with
313 <literal>3</literal>). Use the <literal>BETWEEN</literal> predicates
314 shown below to perform range tests.
315 </para>
317 <para>
318 There are also some comparison predicates, as shown in <xref
319 linkend="functions-comparison-pred-table"/>. These behave much like
320 operators, but have special syntax mandated by the SQL standard.
321 </para>
323 <table id="functions-comparison-pred-table">
324 <title>Comparison Predicates</title>
325 <tgroup cols="1">
326 <thead>
327 <row>
328 <entry role="func_table_entry"><para role="func_signature">
329 Predicate
330 </para>
331 <para>
332 Description
333 </para>
334 <para>
335 Example(s)
336 </para></entry>
337 </row>
338 </thead>
340 <tbody>
341 <row>
342 <entry role="func_table_entry"><para role="func_signature">
343 <replaceable>datatype</replaceable> <literal>BETWEEN</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
344 <returnvalue>boolean</returnvalue>
345 </para>
346 <para>
347 Between (inclusive of the range endpoints).
348 </para>
349 <para>
350 <literal>2 BETWEEN 1 AND 3</literal>
351 <returnvalue>t</returnvalue>
352 </para>
353 <para>
354 <literal>2 BETWEEN 3 AND 1</literal>
355 <returnvalue>f</returnvalue>
356 </para></entry>
357 </row>
359 <row>
360 <entry role="func_table_entry"><para role="func_signature">
361 <replaceable>datatype</replaceable> <literal>NOT BETWEEN</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
362 <returnvalue>boolean</returnvalue>
363 </para>
364 <para>
365 Not between (the negation of <literal>BETWEEN</literal>).
366 </para>
367 <para>
368 <literal>2 NOT BETWEEN 1 AND 3</literal>
369 <returnvalue>f</returnvalue>
370 </para></entry>
371 </row>
373 <row>
374 <entry role="func_table_entry"><para role="func_signature">
375 <replaceable>datatype</replaceable> <literal>BETWEEN SYMMETRIC</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
376 <returnvalue>boolean</returnvalue>
377 </para>
378 <para>
379 Between, after sorting the two endpoint values.
380 </para>
381 <para>
382 <literal>2 BETWEEN SYMMETRIC 3 AND 1</literal>
383 <returnvalue>t</returnvalue>
384 </para></entry>
385 </row>
387 <row>
388 <entry role="func_table_entry"><para role="func_signature">
389 <replaceable>datatype</replaceable> <literal>NOT BETWEEN SYMMETRIC</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
390 <returnvalue>boolean</returnvalue>
391 </para>
392 <para>
393 Not between, after sorting the two endpoint values.
394 </para>
395 <para>
396 <literal>2 NOT BETWEEN SYMMETRIC 3 AND 1</literal>
397 <returnvalue>f</returnvalue>
398 </para></entry>
399 </row>
401 <row>
402 <entry role="func_table_entry"><para role="func_signature">
403 <replaceable>datatype</replaceable> <literal>IS DISTINCT FROM</literal> <replaceable>datatype</replaceable>
404 <returnvalue>boolean</returnvalue>
405 </para>
406 <para>
407 Not equal, treating null as a comparable value.
408 </para>
409 <para>
410 <literal>1 IS DISTINCT FROM NULL</literal>
411 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
412 </para>
413 <para>
414 <literal>NULL IS DISTINCT FROM NULL</literal>
415 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
416 </para></entry>
417 </row>
419 <row>
420 <entry role="func_table_entry"><para role="func_signature">
421 <replaceable>datatype</replaceable> <literal>IS NOT DISTINCT FROM</literal> <replaceable>datatype</replaceable>
422 <returnvalue>boolean</returnvalue>
423 </para>
424 <para>
425 Equal, treating null as a comparable value.
426 </para>
427 <para>
428 <literal>1 IS NOT DISTINCT FROM NULL</literal>
429 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
430 </para>
431 <para>
432 <literal>NULL IS NOT DISTINCT FROM NULL</literal>
433 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
434 </para></entry>
435 </row>
437 <row>
438 <entry role="func_table_entry"><para role="func_signature">
439 <replaceable>datatype</replaceable> <literal>IS NULL</literal>
440 <returnvalue>boolean</returnvalue>
441 </para>
442 <para>
443 Test whether value is null.
444 </para>
445 <para>
446 <literal>1.5 IS NULL</literal>
447 <returnvalue>f</returnvalue>
448 </para></entry>
449 </row>
451 <row>
452 <entry role="func_table_entry"><para role="func_signature">
453 <replaceable>datatype</replaceable> <literal>IS NOT NULL</literal>
454 <returnvalue>boolean</returnvalue>
455 </para>
456 <para>
457 Test whether value is not null.
458 </para>
459 <para>
460 <literal>'null' IS NOT NULL</literal>
461 <returnvalue>t</returnvalue>
462 </para></entry>
463 </row>
465 <row>
466 <entry role="func_table_entry"><para role="func_signature">
467 <replaceable>datatype</replaceable> <literal>ISNULL</literal>
468 <returnvalue>boolean</returnvalue>
469 </para>
470 <para>
471 Test whether value is null (nonstandard syntax).
472 </para></entry>
473 </row>
475 <row>
476 <entry role="func_table_entry"><para role="func_signature">
477 <replaceable>datatype</replaceable> <literal>NOTNULL</literal>
478 <returnvalue>boolean</returnvalue>
479 </para>
480 <para>
481 Test whether value is not null (nonstandard syntax).
482 </para></entry>
483 </row>
485 <row>
486 <entry role="func_table_entry"><para role="func_signature">
487 <type>boolean</type> <literal>IS TRUE</literal>
488 <returnvalue>boolean</returnvalue>
489 </para>
490 <para>
491 Test whether boolean expression yields true.
492 </para>
493 <para>
494 <literal>true IS TRUE</literal>
495 <returnvalue>t</returnvalue>
496 </para>
497 <para>
498 <literal>NULL::boolean IS TRUE</literal>
499 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
500 </para></entry>
501 </row>
503 <row>
504 <entry role="func_table_entry"><para role="func_signature">
505 <type>boolean</type> <literal>IS NOT TRUE</literal>
506 <returnvalue>boolean</returnvalue>
507 </para>
508 <para>
509 Test whether boolean expression yields false or unknown.
510 </para>
511 <para>
512 <literal>true IS NOT TRUE</literal>
513 <returnvalue>f</returnvalue>
514 </para>
515 <para>
516 <literal>NULL::boolean IS NOT TRUE</literal>
517 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
518 </para></entry>
519 </row>
521 <row>
522 <entry role="func_table_entry"><para role="func_signature">
523 <type>boolean</type> <literal>IS FALSE</literal>
524 <returnvalue>boolean</returnvalue>
525 </para>
526 <para>
527 Test whether boolean expression yields false.
528 </para>
529 <para>
530 <literal>true IS FALSE</literal>
531 <returnvalue>f</returnvalue>
532 </para>
533 <para>
534 <literal>NULL::boolean IS FALSE</literal>
535 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
536 </para></entry>
537 </row>
539 <row>
540 <entry role="func_table_entry"><para role="func_signature">
541 <type>boolean</type> <literal>IS NOT FALSE</literal>
542 <returnvalue>boolean</returnvalue>
543 </para>
544 <para>
545 Test whether boolean expression yields true or unknown.
546 </para>
547 <para>
548 <literal>true IS NOT FALSE</literal>
549 <returnvalue>t</returnvalue>
550 </para>
551 <para>
552 <literal>NULL::boolean IS NOT FALSE</literal>
553 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
554 </para></entry>
555 </row>
557 <row>
558 <entry role="func_table_entry"><para role="func_signature">
559 <type>boolean</type> <literal>IS UNKNOWN</literal>
560 <returnvalue>boolean</returnvalue>
561 </para>
562 <para>
563 Test whether boolean expression yields unknown.
564 </para>
565 <para>
566 <literal>true IS UNKNOWN</literal>
567 <returnvalue>f</returnvalue>
568 </para>
569 <para>
570 <literal>NULL::boolean IS UNKNOWN</literal>
571 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
572 </para></entry>
573 </row>
575 <row>
576 <entry role="func_table_entry"><para role="func_signature">
577 <type>boolean</type> <literal>IS NOT UNKNOWN</literal>
578 <returnvalue>boolean</returnvalue>
579 </para>
580 <para>
581 Test whether boolean expression yields true or false.
582 </para>
583 <para>
584 <literal>true IS NOT UNKNOWN</literal>
585 <returnvalue>t</returnvalue>
586 </para>
587 <para>
588 <literal>NULL::boolean IS NOT UNKNOWN</literal>
589 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
590 </para></entry>
591 </row>
592 </tbody>
593 </tgroup>
594 </table>
596 <para>
597 <indexterm>
598 <primary>BETWEEN</primary>
599 </indexterm>
600 <indexterm>
601 <primary>BETWEEN SYMMETRIC</primary>
602 </indexterm>
603 The <token>BETWEEN</token> predicate simplifies range tests:
604 <synopsis>
605 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
606 </synopsis>
607 is equivalent to
608 <synopsis>
609 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
610 </synopsis>
611 Notice that <token>BETWEEN</token> treats the endpoint values as included
612 in the range.
613 <literal>BETWEEN SYMMETRIC</literal> is like <literal>BETWEEN</literal>
614 except there is no requirement that the argument to the left of
615 <literal>AND</literal> be less than or equal to the argument on the right.
616 If it is not, those two arguments are automatically swapped, so that
617 a nonempty range is always implied.
618 </para>
620 <para>
621 The various variants of <literal>BETWEEN</literal> are implemented in
622 terms of the ordinary comparison operators, and therefore will work for
623 any data type(s) that can be compared.
624 </para>
626 <note>
627 <para>
628 The use of <literal>AND</literal> in the <literal>BETWEEN</literal>
629 syntax creates an ambiguity with the use of <literal>AND</literal> as a
630 logical operator. To resolve this, only a limited set of expression
631 types are allowed as the second argument of a <literal>BETWEEN</literal>
632 clause. If you need to write a more complex sub-expression
633 in <literal>BETWEEN</literal>, write parentheses around the
634 sub-expression.
635 </para>
636 </note>
638 <para>
639 <indexterm>
640 <primary>IS DISTINCT FROM</primary>
641 </indexterm>
642 <indexterm>
643 <primary>IS NOT DISTINCT FROM</primary>
644 </indexterm>
645 Ordinary comparison operators yield null (signifying <quote>unknown</quote>),
646 not true or false, when either input is null. For example,
647 <literal>7 = NULL</literal> yields null, as does <literal>7 &lt;&gt; NULL</literal>. When
648 this behavior is not suitable, use the
649 <literal>IS <optional> NOT </optional> DISTINCT FROM</literal> predicates:
650 <synopsis>
651 <replaceable>a</replaceable> IS DISTINCT FROM <replaceable>b</replaceable>
652 <replaceable>a</replaceable> IS NOT DISTINCT FROM <replaceable>b</replaceable>
653 </synopsis>
654 For non-null inputs, <literal>IS DISTINCT FROM</literal> is
655 the same as the <literal>&lt;&gt;</literal> operator. However, if both
656 inputs are null it returns false, and if only one input is
657 null it returns true. Similarly, <literal>IS NOT DISTINCT
658 FROM</literal> is identical to <literal>=</literal> for non-null
659 inputs, but it returns true when both inputs are null, and false when only
660 one input is null. Thus, these predicates effectively act as though null
661 were a normal data value, rather than <quote>unknown</quote>.
662 </para>
664 <para>
665 <indexterm>
666 <primary>IS NULL</primary>
667 </indexterm>
668 <indexterm>
669 <primary>IS NOT NULL</primary>
670 </indexterm>
671 <indexterm>
672 <primary>ISNULL</primary>
673 </indexterm>
674 <indexterm>
675 <primary>NOTNULL</primary>
676 </indexterm>
677 To check whether a value is or is not null, use the predicates:
678 <synopsis>
679 <replaceable>expression</replaceable> IS NULL
680 <replaceable>expression</replaceable> IS NOT NULL
681 </synopsis>
682 or the equivalent, but nonstandard, predicates:
683 <synopsis>
684 <replaceable>expression</replaceable> ISNULL
685 <replaceable>expression</replaceable> NOTNULL
686 </synopsis>
687 <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
688 </para>
690 <para>
691 Do <emphasis>not</emphasis> write
692 <literal><replaceable>expression</replaceable> = NULL</literal>
693 because <literal>NULL</literal> is not <quote>equal to</quote>
694 <literal>NULL</literal>. (The null value represents an unknown value,
695 and it is not known whether two unknown values are equal.)
696 </para>
698 <tip>
699 <para>
700 Some applications might expect that
701 <literal><replaceable>expression</replaceable> = NULL</literal>
702 returns true if <replaceable>expression</replaceable> evaluates to
703 the null value. It is highly recommended that these applications
704 be modified to comply with the SQL standard. However, if that
705 cannot be done the <xref linkend="guc-transform-null-equals"/>
706 configuration variable is available. If it is enabled,
707 <productname>PostgreSQL</productname> will convert <literal>x =
708 NULL</literal> clauses to <literal>x IS NULL</literal>.
709 </para>
710 </tip>
712 <para>
713 If the <replaceable>expression</replaceable> is row-valued, then
714 <literal>IS NULL</literal> is true when the row expression itself is null
715 or when all the row's fields are null, while
716 <literal>IS NOT NULL</literal> is true when the row expression itself is non-null
717 and all the row's fields are non-null. Because of this behavior,
718 <literal>IS NULL</literal> and <literal>IS NOT NULL</literal> do not always return
719 inverse results for row-valued expressions; in particular, a row-valued
720 expression that contains both null and non-null fields will return false
721 for both tests. In some cases, it may be preferable to
722 write <replaceable>row</replaceable> <literal>IS DISTINCT FROM NULL</literal>
723 or <replaceable>row</replaceable> <literal>IS NOT DISTINCT FROM NULL</literal>,
724 which will simply check whether the overall row value is null without any
725 additional tests on the row fields.
726 </para>
728 <para>
729 <indexterm>
730 <primary>IS TRUE</primary>
731 </indexterm>
732 <indexterm>
733 <primary>IS NOT TRUE</primary>
734 </indexterm>
735 <indexterm>
736 <primary>IS FALSE</primary>
737 </indexterm>
738 <indexterm>
739 <primary>IS NOT FALSE</primary>
740 </indexterm>
741 <indexterm>
742 <primary>IS UNKNOWN</primary>
743 </indexterm>
744 <indexterm>
745 <primary>IS NOT UNKNOWN</primary>
746 </indexterm>
747 Boolean values can also be tested using the predicates
748 <synopsis>
749 <replaceable>boolean_expression</replaceable> IS TRUE
750 <replaceable>boolean_expression</replaceable> IS NOT TRUE
751 <replaceable>boolean_expression</replaceable> IS FALSE
752 <replaceable>boolean_expression</replaceable> IS NOT FALSE
753 <replaceable>boolean_expression</replaceable> IS UNKNOWN
754 <replaceable>boolean_expression</replaceable> IS NOT UNKNOWN
755 </synopsis>
756 These will always return true or false, never a null value, even when the
757 operand is null.
758 A null input is treated as the logical value <quote>unknown</quote>.
759 Notice that <literal>IS UNKNOWN</literal> and <literal>IS NOT UNKNOWN</literal> are
760 effectively the same as <literal>IS NULL</literal> and
761 <literal>IS NOT NULL</literal>, respectively, except that the input
762 expression must be of Boolean type.
763 </para>
765 <para>
766 Some comparison-related functions are also available, as shown in <xref
767 linkend="functions-comparison-func-table"/>.
768 </para>
770 <table id="functions-comparison-func-table">
771 <title>Comparison Functions</title>
772 <tgroup cols="1">
773 <thead>
774 <row>
775 <entry role="func_table_entry"><para role="func_signature">
776 Function
777 </para>
778 <para>
779 Description
780 </para>
781 <para>
782 Example(s)
783 </para></entry>
784 </row>
785 </thead>
787 <tbody>
788 <row>
789 <entry role="func_table_entry"><para role="func_signature">
790 <indexterm>
791 <primary>num_nonnulls</primary>
792 </indexterm>
793 <function>num_nonnulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
794 <returnvalue>integer</returnvalue>
795 </para>
796 <para>
797 Returns the number of non-null arguments.
798 </para>
799 <para>
800 <literal>num_nonnulls(1, NULL, 2)</literal>
801 <returnvalue>2</returnvalue>
802 </para></entry>
803 </row>
804 <row>
805 <entry role="func_table_entry"><para role="func_signature">
806 <indexterm>
807 <primary>num_nulls</primary>
808 </indexterm>
809 <function>num_nulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
810 <returnvalue>integer</returnvalue>
811 </para>
812 <para>
813 Returns the number of null arguments.
814 </para>
815 <para>
816 <literal>num_nulls(1, NULL, 2)</literal>
817 <returnvalue>1</returnvalue>
818 </para></entry>
819 </row>
820 </tbody>
821 </tgroup>
822 </table>
824 </sect1>
826 <sect1 id="functions-math">
827 <title>Mathematical Functions and Operators</title>
829 <para>
830 Mathematical operators are provided for many
831 <productname>PostgreSQL</productname> types. For types without
832 standard mathematical conventions
833 (e.g., date/time types) we
834 describe the actual behavior in subsequent sections.
835 </para>
837 <para>
838 <xref linkend="functions-math-op-table"/> shows the mathematical
839 operators that are available for the standard numeric types.
840 Unless otherwise noted, operators shown as
841 accepting <replaceable>numeric_type</replaceable> are available for all
842 the types <type>smallint</type>, <type>integer</type>,
843 <type>bigint</type>, <type>numeric</type>, <type>real</type>,
844 and <type>double precision</type>.
845 Operators shown as accepting <replaceable>integral_type</replaceable>
846 are available for the types <type>smallint</type>, <type>integer</type>,
847 and <type>bigint</type>.
848 Except where noted, each form of an operator returns the same data type
849 as its argument(s). Calls involving multiple argument data types, such
850 as <type>integer</type> <literal>+</literal> <type>numeric</type>,
851 are resolved by using the type appearing later in these lists.
852 </para>
854 <table id="functions-math-op-table">
855 <title>Mathematical Operators</title>
857 <tgroup cols="1">
858 <thead>
859 <row>
860 <entry role="func_table_entry"><para role="func_signature">
861 Operator
862 </para>
863 <para>
864 Description
865 </para>
866 <para>
867 Example(s)
868 </para></entry>
869 </row>
870 </thead>
872 <tbody>
873 <row>
874 <entry role="func_table_entry"><para role="func_signature">
875 <replaceable>numeric_type</replaceable> <literal>+</literal> <replaceable>numeric_type</replaceable>
876 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
877 </para>
878 <para>
879 Addition
880 </para>
881 <para>
882 <literal>2 + 3</literal>
883 <returnvalue>5</returnvalue>
884 </para></entry>
885 </row>
887 <row>
888 <entry role="func_table_entry"><para role="func_signature">
889 <literal>+</literal> <replaceable>numeric_type</replaceable>
890 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
891 </para>
892 <para>
893 Unary plus (no operation)
894 </para>
895 <para>
896 <literal>+ 3.5</literal>
897 <returnvalue>3.5</returnvalue>
898 </para></entry>
899 </row>
901 <row>
902 <entry role="func_table_entry"><para role="func_signature">
903 <replaceable>numeric_type</replaceable> <literal>-</literal> <replaceable>numeric_type</replaceable>
904 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
905 </para>
906 <para>
907 Subtraction
908 </para>
909 <para>
910 <literal>2 - 3</literal>
911 <returnvalue>-1</returnvalue>
912 </para></entry>
913 </row>
915 <row>
916 <entry role="func_table_entry"><para role="func_signature">
917 <literal>-</literal> <replaceable>numeric_type</replaceable>
918 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
919 </para>
920 <para>
921 Negation
922 </para>
923 <para>
924 <literal>- (-4)</literal>
925 <returnvalue>4</returnvalue>
926 </para></entry>
927 </row>
929 <row>
930 <entry role="func_table_entry"><para role="func_signature">
931 <replaceable>numeric_type</replaceable> <literal>*</literal> <replaceable>numeric_type</replaceable>
932 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
933 </para>
934 <para>
935 Multiplication
936 </para>
937 <para>
938 <literal>2 * 3</literal>
939 <returnvalue>6</returnvalue>
940 </para></entry>
941 </row>
943 <row>
944 <entry role="func_table_entry"><para role="func_signature">
945 <replaceable>numeric_type</replaceable> <literal>/</literal> <replaceable>numeric_type</replaceable>
946 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
947 </para>
948 <para>
949 Division (for integral types, division truncates the result towards
950 zero)
951 </para>
952 <para>
953 <literal>5.0 / 2</literal>
954 <returnvalue>2.5000000000000000</returnvalue>
955 </para>
956 <para>
957 <literal>5 / 2</literal>
958 <returnvalue>2</returnvalue>
959 </para>
960 <para>
961 <literal>(-5) / 2</literal>
962 <returnvalue>-2</returnvalue>
963 </para></entry>
964 </row>
966 <row>
967 <entry role="func_table_entry"><para role="func_signature">
968 <replaceable>numeric_type</replaceable> <literal>%</literal> <replaceable>numeric_type</replaceable>
969 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
970 </para>
971 <para>
972 Modulo (remainder); available for <type>smallint</type>,
973 <type>integer</type>, <type>bigint</type>, and <type>numeric</type>
974 </para>
975 <para>
976 <literal>5 % 4</literal>
977 <returnvalue>1</returnvalue>
978 </para></entry>
979 </row>
981 <row>
982 <entry role="func_table_entry"><para role="func_signature">
983 <type>numeric</type> <literal>^</literal> <type>numeric</type>
984 <returnvalue>numeric</returnvalue>
985 </para>
986 <para role="func_signature">
987 <type>double precision</type> <literal>^</literal> <type>double precision</type>
988 <returnvalue>double precision</returnvalue>
989 </para>
990 <para>
991 Exponentiation
992 </para>
993 <para>
994 <literal>2 ^ 3</literal>
995 <returnvalue>8</returnvalue>
996 </para>
997 <para>
998 Unlike typical mathematical practice, multiple uses of
999 <literal>^</literal> will associate left to right by default:
1000 </para>
1001 <para>
1002 <literal>2 ^ 3 ^ 3</literal>
1003 <returnvalue>512</returnvalue>
1004 </para>
1005 <para>
1006 <literal>2 ^ (3 ^ 3)</literal>
1007 <returnvalue>134217728</returnvalue>
1008 </para></entry>
1009 </row>
1011 <row>
1012 <entry role="func_table_entry"><para role="func_signature">
1013 <literal>|/</literal> <type>double precision</type>
1014 <returnvalue>double precision</returnvalue>
1015 </para>
1016 <para>
1017 Square root
1018 </para>
1019 <para>
1020 <literal>|/ 25.0</literal>
1021 <returnvalue>5</returnvalue>
1022 </para></entry>
1023 </row>
1025 <row>
1026 <entry role="func_table_entry"><para role="func_signature">
1027 <literal>||/</literal> <type>double precision</type>
1028 <returnvalue>double precision</returnvalue>
1029 </para>
1030 <para>
1031 Cube root
1032 </para>
1033 <para>
1034 <literal>||/ 64.0</literal>
1035 <returnvalue>4</returnvalue>
1036 </para></entry>
1037 </row>
1039 <row>
1040 <entry role="func_table_entry"><para role="func_signature">
1041 <literal>@</literal> <replaceable>numeric_type</replaceable>
1042 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1043 </para>
1044 <para>
1045 Absolute value
1046 </para>
1047 <para>
1048 <literal>@ -5.0</literal>
1049 <returnvalue>5.0</returnvalue>
1050 </para></entry>
1051 </row>
1053 <row>
1054 <entry role="func_table_entry"><para role="func_signature">
1055 <replaceable>integral_type</replaceable> <literal>&amp;</literal> <replaceable>integral_type</replaceable>
1056 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1057 </para>
1058 <para>
1059 Bitwise AND
1060 </para>
1061 <para>
1062 <literal>91 &amp; 15</literal>
1063 <returnvalue>11</returnvalue>
1064 </para></entry>
1065 </row>
1067 <row>
1068 <entry role="func_table_entry"><para role="func_signature">
1069 <replaceable>integral_type</replaceable> <literal>|</literal> <replaceable>integral_type</replaceable>
1070 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1071 </para>
1072 <para>
1073 Bitwise OR
1074 </para>
1075 <para>
1076 <literal>32 | 3</literal>
1077 <returnvalue>35</returnvalue>
1078 </para></entry>
1079 </row>
1081 <row>
1082 <entry role="func_table_entry"><para role="func_signature">
1083 <replaceable>integral_type</replaceable> <literal>#</literal> <replaceable>integral_type</replaceable>
1084 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1085 </para>
1086 <para>
1087 Bitwise exclusive OR
1088 </para>
1089 <para>
1090 <literal>17 # 5</literal>
1091 <returnvalue>20</returnvalue>
1092 </para></entry>
1093 </row>
1095 <row>
1096 <entry role="func_table_entry"><para role="func_signature">
1097 <literal>~</literal> <replaceable>integral_type</replaceable>
1098 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1099 </para>
1100 <para>
1101 Bitwise NOT
1102 </para>
1103 <para>
1104 <literal>~1</literal>
1105 <returnvalue>-2</returnvalue>
1106 </para></entry>
1107 </row>
1109 <row>
1110 <entry role="func_table_entry"><para role="func_signature">
1111 <replaceable>integral_type</replaceable> <literal>&lt;&lt;</literal> <type>integer</type>
1112 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1113 </para>
1114 <para>
1115 Bitwise shift left
1116 </para>
1117 <para>
1118 <literal>1 &lt;&lt; 4</literal>
1119 <returnvalue>16</returnvalue>
1120 </para></entry>
1121 </row>
1123 <row>
1124 <entry role="func_table_entry"><para role="func_signature">
1125 <replaceable>integral_type</replaceable> <literal>&gt;&gt;</literal> <type>integer</type>
1126 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1127 </para>
1128 <para>
1129 Bitwise shift right
1130 </para>
1131 <para>
1132 <literal>8 &gt;&gt; 2</literal>
1133 <returnvalue>2</returnvalue>
1134 </para></entry>
1135 </row>
1137 </tbody>
1138 </tgroup>
1139 </table>
1141 <para>
1142 <xref linkend="functions-math-func-table"/> shows the available
1143 mathematical functions.
1144 Many of these functions are provided in multiple forms with different
1145 argument types.
1146 Except where noted, any given form of a function returns the same
1147 data type as its argument(s); cross-type cases are resolved in the
1148 same way as explained above for operators.
1149 The functions working with <type>double precision</type> data are mostly
1150 implemented on top of the host system's C library; accuracy and behavior in
1151 boundary cases can therefore vary depending on the host system.
1152 </para>
1154 <table id="functions-math-func-table">
1155 <title>Mathematical Functions</title>
1156 <tgroup cols="1">
1157 <thead>
1158 <row>
1159 <entry role="func_table_entry"><para role="func_signature">
1160 Function
1161 </para>
1162 <para>
1163 Description
1164 </para>
1165 <para>
1166 Example(s)
1167 </para></entry>
1168 </row>
1169 </thead>
1171 <tbody>
1172 <row>
1173 <entry role="func_table_entry"><para role="func_signature">
1174 <indexterm>
1175 <primary>abs</primary>
1176 </indexterm>
1177 <function>abs</function> ( <replaceable>numeric_type</replaceable> )
1178 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1179 </para>
1180 <para>
1181 Absolute value
1182 </para>
1183 <para>
1184 <literal>abs(-17.4)</literal>
1185 <returnvalue>17.4</returnvalue>
1186 </para></entry>
1187 </row>
1189 <row>
1190 <entry role="func_table_entry"><para role="func_signature">
1191 <indexterm>
1192 <primary>cbrt</primary>
1193 </indexterm>
1194 <function>cbrt</function> ( <type>double precision</type> )
1195 <returnvalue>double precision</returnvalue>
1196 </para>
1197 <para>
1198 Cube root
1199 </para>
1200 <para>
1201 <literal>cbrt(64.0)</literal>
1202 <returnvalue>4</returnvalue>
1203 </para></entry>
1204 </row>
1206 <row>
1207 <entry role="func_table_entry"><para role="func_signature">
1208 <indexterm>
1209 <primary>ceil</primary>
1210 </indexterm>
1211 <function>ceil</function> ( <type>numeric</type> )
1212 <returnvalue>numeric</returnvalue>
1213 </para>
1214 <para role="func_signature">
1215 <function>ceil</function> ( <type>double precision</type> )
1216 <returnvalue>double precision</returnvalue>
1217 </para>
1218 <para>
1219 Nearest integer greater than or equal to argument
1220 </para>
1221 <para>
1222 <literal>ceil(42.2)</literal>
1223 <returnvalue>43</returnvalue>
1224 </para>
1225 <para>
1226 <literal>ceil(-42.8)</literal>
1227 <returnvalue>-42</returnvalue>
1228 </para></entry>
1229 </row>
1231 <row>
1232 <entry role="func_table_entry"><para role="func_signature">
1233 <indexterm>
1234 <primary>ceiling</primary>
1235 </indexterm>
1236 <function>ceiling</function> ( <type>numeric</type> )
1237 <returnvalue>numeric</returnvalue>
1238 </para>
1239 <para role="func_signature">
1240 <function>ceiling</function> ( <type>double precision</type> )
1241 <returnvalue>double precision</returnvalue>
1242 </para>
1243 <para>
1244 Nearest integer greater than or equal to argument (same
1245 as <function>ceil</function>)
1246 </para>
1247 <para>
1248 <literal>ceiling(95.3)</literal>
1249 <returnvalue>96</returnvalue>
1250 </para></entry>
1251 </row>
1253 <row>
1254 <entry role="func_table_entry"><para role="func_signature">
1255 <indexterm>
1256 <primary>degrees</primary>
1257 </indexterm>
1258 <function>degrees</function> ( <type>double precision</type> )
1259 <returnvalue>double precision</returnvalue>
1260 </para>
1261 <para>
1262 Converts radians to degrees
1263 </para>
1264 <para>
1265 <literal>degrees(0.5)</literal>
1266 <returnvalue>28.64788975654116</returnvalue>
1267 </para></entry>
1268 </row>
1270 <row>
1271 <entry role="func_table_entry"><para role="func_signature">
1272 <indexterm>
1273 <primary>div</primary>
1274 </indexterm>
1275 <function>div</function> ( <parameter>y</parameter> <type>numeric</type>,
1276 <parameter>x</parameter> <type>numeric</type> )
1277 <returnvalue>numeric</returnvalue>
1278 </para>
1279 <para>
1280 Integer quotient of <parameter>y</parameter>/<parameter>x</parameter>
1281 (truncates towards zero)
1282 </para>
1283 <para>
1284 <literal>div(9, 4)</literal>
1285 <returnvalue>2</returnvalue>
1286 </para></entry>
1287 </row>
1289 <row>
1290 <entry role="func_table_entry"><para role="func_signature">
1291 <indexterm>
1292 <primary>erf</primary>
1293 </indexterm>
1294 <function>erf</function> ( <type>double precision</type> )
1295 <returnvalue>double precision</returnvalue>
1296 </para>
1297 <para>
1298 Error function
1299 </para>
1300 <para>
1301 <literal>erf(1.0)</literal>
1302 <returnvalue>0.8427007929497149</returnvalue>
1303 </para></entry>
1304 </row>
1306 <row>
1307 <entry role="func_table_entry"><para role="func_signature">
1308 <indexterm>
1309 <primary>erfc</primary>
1310 </indexterm>
1311 <function>erfc</function> ( <type>double precision</type> )
1312 <returnvalue>double precision</returnvalue>
1313 </para>
1314 <para>
1315 Complementary error function (<literal>1 - erf(x)</literal>, without
1316 loss of precision for large inputs)
1317 </para>
1318 <para>
1319 <literal>erfc(1.0)</literal>
1320 <returnvalue>0.15729920705028513</returnvalue>
1321 </para></entry>
1322 </row>
1324 <row>
1325 <entry role="func_table_entry"><para role="func_signature">
1326 <indexterm>
1327 <primary>exp</primary>
1328 </indexterm>
1329 <function>exp</function> ( <type>numeric</type> )
1330 <returnvalue>numeric</returnvalue>
1331 </para>
1332 <para role="func_signature">
1333 <function>exp</function> ( <type>double precision</type> )
1334 <returnvalue>double precision</returnvalue>
1335 </para>
1336 <para>
1337 Exponential (<literal>e</literal> raised to the given power)
1338 </para>
1339 <para>
1340 <literal>exp(1.0)</literal>
1341 <returnvalue>2.7182818284590452</returnvalue>
1342 </para></entry>
1343 </row>
1345 <row>
1346 <entry role="func_table_entry"><para role="func_signature">
1347 <indexterm id="function-factorial">
1348 <primary>factorial</primary>
1349 </indexterm>
1350 <function>factorial</function> ( <type>bigint</type> )
1351 <returnvalue>numeric</returnvalue>
1352 </para>
1353 <para>
1354 Factorial
1355 </para>
1356 <para>
1357 <literal>factorial(5)</literal>
1358 <returnvalue>120</returnvalue>
1359 </para></entry>
1360 </row>
1362 <row>
1363 <entry role="func_table_entry"><para role="func_signature">
1364 <indexterm>
1365 <primary>floor</primary>
1366 </indexterm>
1367 <function>floor</function> ( <type>numeric</type> )
1368 <returnvalue>numeric</returnvalue>
1369 </para>
1370 <para role="func_signature">
1371 <function>floor</function> ( <type>double precision</type> )
1372 <returnvalue>double precision</returnvalue>
1373 </para>
1374 <para>
1375 Nearest integer less than or equal to argument
1376 </para>
1377 <para>
1378 <literal>floor(42.8)</literal>
1379 <returnvalue>42</returnvalue>
1380 </para>
1381 <para>
1382 <literal>floor(-42.8)</literal>
1383 <returnvalue>-43</returnvalue>
1384 </para></entry>
1385 </row>
1387 <row>
1388 <entry role="func_table_entry"><para role="func_signature">
1389 <indexterm>
1390 <primary>gcd</primary>
1391 </indexterm>
1392 <function>gcd</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> )
1393 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1394 </para>
1395 <para>
1396 Greatest common divisor (the largest positive number that divides both
1397 inputs with no remainder); returns <literal>0</literal> if both inputs
1398 are zero; available for <type>integer</type>, <type>bigint</type>,
1399 and <type>numeric</type>
1400 </para>
1401 <para>
1402 <literal>gcd(1071, 462)</literal>
1403 <returnvalue>21</returnvalue>
1404 </para></entry>
1405 </row>
1407 <row>
1408 <entry role="func_table_entry"><para role="func_signature">
1409 <indexterm>
1410 <primary>lcm</primary>
1411 </indexterm>
1412 <function>lcm</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> )
1413 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1414 </para>
1415 <para>
1416 Least common multiple (the smallest strictly positive number that is
1417 an integral multiple of both inputs); returns <literal>0</literal> if
1418 either input is zero; available for <type>integer</type>,
1419 <type>bigint</type>, and <type>numeric</type>
1420 </para>
1421 <para>
1422 <literal>lcm(1071, 462)</literal>
1423 <returnvalue>23562</returnvalue>
1424 </para></entry>
1425 </row>
1427 <row>
1428 <entry role="func_table_entry"><para role="func_signature">
1429 <indexterm>
1430 <primary>ln</primary>
1431 </indexterm>
1432 <function>ln</function> ( <type>numeric</type> )
1433 <returnvalue>numeric</returnvalue>
1434 </para>
1435 <para role="func_signature">
1436 <function>ln</function> ( <type>double precision</type> )
1437 <returnvalue>double precision</returnvalue>
1438 </para>
1439 <para>
1440 Natural logarithm
1441 </para>
1442 <para>
1443 <literal>ln(2.0)</literal>
1444 <returnvalue>0.6931471805599453</returnvalue>
1445 </para></entry>
1446 </row>
1448 <row>
1449 <entry role="func_table_entry"><para role="func_signature">
1450 <indexterm>
1451 <primary>log</primary>
1452 </indexterm>
1453 <function>log</function> ( <type>numeric</type> )
1454 <returnvalue>numeric</returnvalue>
1455 </para>
1456 <para role="func_signature">
1457 <function>log</function> ( <type>double precision</type> )
1458 <returnvalue>double precision</returnvalue>
1459 </para>
1460 <para>
1461 Base 10 logarithm
1462 </para>
1463 <para>
1464 <literal>log(100)</literal>
1465 <returnvalue>2</returnvalue>
1466 </para></entry>
1467 </row>
1469 <row>
1470 <entry role="func_table_entry"><para role="func_signature">
1471 <indexterm>
1472 <primary>log10</primary>
1473 </indexterm>
1474 <function>log10</function> ( <type>numeric</type> )
1475 <returnvalue>numeric</returnvalue>
1476 </para>
1477 <para role="func_signature">
1478 <function>log10</function> ( <type>double precision</type> )
1479 <returnvalue>double precision</returnvalue>
1480 </para>
1481 <para>
1482 Base 10 logarithm (same as <function>log</function>)
1483 </para>
1484 <para>
1485 <literal>log10(1000)</literal>
1486 <returnvalue>3</returnvalue>
1487 </para></entry>
1488 </row>
1490 <row>
1491 <entry role="func_table_entry"><para role="func_signature">
1492 <function>log</function> ( <parameter>b</parameter> <type>numeric</type>,
1493 <parameter>x</parameter> <type>numeric</type> )
1494 <returnvalue>numeric</returnvalue>
1495 </para>
1496 <para>
1497 Logarithm of <parameter>x</parameter> to base <parameter>b</parameter>
1498 </para>
1499 <para>
1500 <literal>log(2.0, 64.0)</literal>
1501 <returnvalue>6.0000000000000000</returnvalue>
1502 </para></entry>
1503 </row>
1505 <row>
1506 <entry role="func_table_entry"><para role="func_signature">
1507 <indexterm>
1508 <primary>min_scale</primary>
1509 </indexterm>
1510 <function>min_scale</function> ( <type>numeric</type> )
1511 <returnvalue>integer</returnvalue>
1512 </para>
1513 <para>
1514 Minimum scale (number of fractional decimal digits) needed
1515 to represent the supplied value precisely
1516 </para>
1517 <para>
1518 <literal>min_scale(8.4100)</literal>
1519 <returnvalue>2</returnvalue>
1520 </para></entry>
1521 </row>
1523 <row>
1524 <entry role="func_table_entry"><para role="func_signature">
1525 <indexterm>
1526 <primary>mod</primary>
1527 </indexterm>
1528 <function>mod</function> ( <parameter>y</parameter> <replaceable>numeric_type</replaceable>,
1529 <parameter>x</parameter> <replaceable>numeric_type</replaceable> )
1530 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1531 </para>
1532 <para>
1533 Remainder of <parameter>y</parameter>/<parameter>x</parameter>;
1534 available for <type>smallint</type>, <type>integer</type>,
1535 <type>bigint</type>, and <type>numeric</type>
1536 </para>
1537 <para>
1538 <literal>mod(9, 4)</literal>
1539 <returnvalue>1</returnvalue>
1540 </para></entry>
1541 </row>
1543 <row>
1544 <entry role="func_table_entry"><para role="func_signature">
1545 <indexterm>
1546 <primary>pi</primary>
1547 </indexterm>
1548 <function>pi</function> ( )
1549 <returnvalue>double precision</returnvalue>
1550 </para>
1551 <para>
1552 Approximate value of <phrase role="symbol_font">&pi;</phrase>
1553 </para>
1554 <para>
1555 <literal>pi()</literal>
1556 <returnvalue>3.141592653589793</returnvalue>
1557 </para></entry>
1558 </row>
1560 <row>
1561 <entry role="func_table_entry"><para role="func_signature">
1562 <indexterm>
1563 <primary>power</primary>
1564 </indexterm>
1565 <function>power</function> ( <parameter>a</parameter> <type>numeric</type>,
1566 <parameter>b</parameter> <type>numeric</type> )
1567 <returnvalue>numeric</returnvalue>
1568 </para>
1569 <para role="func_signature">
1570 <function>power</function> ( <parameter>a</parameter> <type>double precision</type>,
1571 <parameter>b</parameter> <type>double precision</type> )
1572 <returnvalue>double precision</returnvalue>
1573 </para>
1574 <para>
1575 <parameter>a</parameter> raised to the power of <parameter>b</parameter>
1576 </para>
1577 <para>
1578 <literal>power(9, 3)</literal>
1579 <returnvalue>729</returnvalue>
1580 </para></entry>
1581 </row>
1583 <row>
1584 <entry role="func_table_entry"><para role="func_signature">
1585 <indexterm>
1586 <primary>radians</primary>
1587 </indexterm>
1588 <function>radians</function> ( <type>double precision</type> )
1589 <returnvalue>double precision</returnvalue>
1590 </para>
1591 <para>
1592 Converts degrees to radians
1593 </para>
1594 <para>
1595 <literal>radians(45.0)</literal>
1596 <returnvalue>0.7853981633974483</returnvalue>
1597 </para></entry>
1598 </row>
1600 <row>
1601 <entry role="func_table_entry"><para role="func_signature">
1602 <indexterm>
1603 <primary>round</primary>
1604 </indexterm>
1605 <function>round</function> ( <type>numeric</type> )
1606 <returnvalue>numeric</returnvalue>
1607 </para>
1608 <para role="func_signature">
1609 <function>round</function> ( <type>double precision</type> )
1610 <returnvalue>double precision</returnvalue>
1611 </para>
1612 <para>
1613 Rounds to nearest integer. For <type>numeric</type>, ties are
1614 broken by rounding away from zero. For <type>double precision</type>,
1615 the tie-breaking behavior is platform dependent, but
1616 <quote>round to nearest even</quote> is the most common rule.
1617 </para>
1618 <para>
1619 <literal>round(42.4)</literal>
1620 <returnvalue>42</returnvalue>
1621 </para></entry>
1622 </row>
1624 <row>
1625 <entry role="func_table_entry"><para role="func_signature">
1626 <function>round</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> )
1627 <returnvalue>numeric</returnvalue>
1628 </para>
1629 <para>
1630 Rounds <parameter>v</parameter> to <parameter>s</parameter> decimal
1631 places. Ties are broken by rounding away from zero.
1632 </para>
1633 <para>
1634 <literal>round(42.4382, 2)</literal>
1635 <returnvalue>42.44</returnvalue>
1636 </para>
1637 <para>
1638 <literal>round(1234.56, -1)</literal>
1639 <returnvalue>1230</returnvalue>
1640 </para></entry>
1641 </row>
1643 <row>
1644 <entry role="func_table_entry"><para role="func_signature">
1645 <indexterm>
1646 <primary>scale</primary>
1647 </indexterm>
1648 <function>scale</function> ( <type>numeric</type> )
1649 <returnvalue>integer</returnvalue>
1650 </para>
1651 <para>
1652 Scale of the argument (the number of decimal digits in the fractional part)
1653 </para>
1654 <para>
1655 <literal>scale(8.4100)</literal>
1656 <returnvalue>4</returnvalue>
1657 </para></entry>
1658 </row>
1660 <row>
1661 <entry role="func_table_entry"><para role="func_signature">
1662 <indexterm>
1663 <primary>sign</primary>
1664 </indexterm>
1665 <function>sign</function> ( <type>numeric</type> )
1666 <returnvalue>numeric</returnvalue>
1667 </para>
1668 <para role="func_signature">
1669 <function>sign</function> ( <type>double precision</type> )
1670 <returnvalue>double precision</returnvalue>
1671 </para>
1672 <para>
1673 Sign of the argument (-1, 0, or +1)
1674 </para>
1675 <para>
1676 <literal>sign(-8.4)</literal>
1677 <returnvalue>-1</returnvalue>
1678 </para></entry>
1679 </row>
1681 <row>
1682 <entry role="func_table_entry"><para role="func_signature">
1683 <indexterm>
1684 <primary>sqrt</primary>
1685 </indexterm>
1686 <function>sqrt</function> ( <type>numeric</type> )
1687 <returnvalue>numeric</returnvalue>
1688 </para>
1689 <para role="func_signature">
1690 <function>sqrt</function> ( <type>double precision</type> )
1691 <returnvalue>double precision</returnvalue>
1692 </para>
1693 <para>
1694 Square root
1695 </para>
1696 <para>
1697 <literal>sqrt(2)</literal>
1698 <returnvalue>1.4142135623730951</returnvalue>
1699 </para></entry>
1700 </row>
1702 <row>
1703 <entry role="func_table_entry"><para role="func_signature">
1704 <indexterm>
1705 <primary>trim_scale</primary>
1706 </indexterm>
1707 <function>trim_scale</function> ( <type>numeric</type> )
1708 <returnvalue>numeric</returnvalue>
1709 </para>
1710 <para>
1711 Reduces the value's scale (number of fractional decimal digits) by
1712 removing trailing zeroes
1713 </para>
1714 <para>
1715 <literal>trim_scale(8.4100)</literal>
1716 <returnvalue>8.41</returnvalue>
1717 </para></entry>
1718 </row>
1720 <row>
1721 <entry role="func_table_entry"><para role="func_signature">
1722 <indexterm>
1723 <primary>trunc</primary>
1724 </indexterm>
1725 <function>trunc</function> ( <type>numeric</type> )
1726 <returnvalue>numeric</returnvalue>
1727 </para>
1728 <para role="func_signature">
1729 <function>trunc</function> ( <type>double precision</type> )
1730 <returnvalue>double precision</returnvalue>
1731 </para>
1732 <para>
1733 Truncates to integer (towards zero)
1734 </para>
1735 <para>
1736 <literal>trunc(42.8)</literal>
1737 <returnvalue>42</returnvalue>
1738 </para>
1739 <para>
1740 <literal>trunc(-42.8)</literal>
1741 <returnvalue>-42</returnvalue>
1742 </para></entry>
1743 </row>
1745 <row>
1746 <entry role="func_table_entry"><para role="func_signature">
1747 <function>trunc</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> )
1748 <returnvalue>numeric</returnvalue>
1749 </para>
1750 <para>
1751 Truncates <parameter>v</parameter> to <parameter>s</parameter>
1752 decimal places
1753 </para>
1754 <para>
1755 <literal>trunc(42.4382, 2)</literal>
1756 <returnvalue>42.43</returnvalue>
1757 </para></entry>
1758 </row>
1760 <row>
1761 <entry role="func_table_entry"><para role="func_signature">
1762 <indexterm>
1763 <primary>width_bucket</primary>
1764 </indexterm>
1765 <function>width_bucket</function> ( <parameter>operand</parameter> <type>numeric</type>, <parameter>low</parameter> <type>numeric</type>, <parameter>high</parameter> <type>numeric</type>, <parameter>count</parameter> <type>integer</type> )
1766 <returnvalue>integer</returnvalue>
1767 </para>
1768 <para role="func_signature">
1769 <function>width_bucket</function> ( <parameter>operand</parameter> <type>double precision</type>, <parameter>low</parameter> <type>double precision</type>, <parameter>high</parameter> <type>double precision</type>, <parameter>count</parameter> <type>integer</type> )
1770 <returnvalue>integer</returnvalue>
1771 </para>
1772 <para>
1773 Returns the number of the bucket in
1774 which <parameter>operand</parameter> falls in a histogram
1775 having <parameter>count</parameter> equal-width buckets spanning the
1776 range <parameter>low</parameter> to <parameter>high</parameter>.
1777 Returns <literal>0</literal>
1778 or <literal><parameter>count</parameter>+1</literal> for an input
1779 outside that range.
1780 </para>
1781 <para>
1782 <literal>width_bucket(5.35, 0.024, 10.06, 5)</literal>
1783 <returnvalue>3</returnvalue>
1784 </para></entry>
1785 </row>
1787 <row>
1788 <entry role="func_table_entry"><para role="func_signature">
1789 <function>width_bucket</function> ( <parameter>operand</parameter> <type>anycompatible</type>, <parameter>thresholds</parameter> <type>anycompatiblearray</type> )
1790 <returnvalue>integer</returnvalue>
1791 </para>
1792 <para>
1793 Returns the number of the bucket in
1794 which <parameter>operand</parameter> falls given an array listing the
1795 lower bounds of the buckets. Returns <literal>0</literal> for an
1796 input less than the first lower
1797 bound. <parameter>operand</parameter> and the array elements can be
1798 of any type having standard comparison operators.
1799 The <parameter>thresholds</parameter> array <emphasis>must be
1800 sorted</emphasis>, smallest first, or unexpected results will be
1801 obtained.
1802 </para>
1803 <para>
1804 <literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])</literal>
1805 <returnvalue>2</returnvalue>
1806 </para></entry>
1807 </row>
1808 </tbody>
1809 </tgroup>
1810 </table>
1812 <para>
1813 <xref linkend="functions-math-random-table"/> shows functions for
1814 generating random numbers.
1815 </para>
1817 <table id="functions-math-random-table">
1818 <title>Random Functions</title>
1820 <tgroup cols="1">
1821 <thead>
1822 <row>
1823 <entry role="func_table_entry"><para role="func_signature">
1824 Function
1825 </para>
1826 <para>
1827 Description
1828 </para>
1829 <para>
1830 Example(s)
1831 </para></entry>
1832 </row>
1833 </thead>
1835 <tbody>
1836 <row>
1837 <entry role="func_table_entry"><para role="func_signature">
1838 <indexterm>
1839 <primary>random</primary>
1840 </indexterm>
1841 <function>random</function> ( )
1842 <returnvalue>double precision</returnvalue>
1843 </para>
1844 <para>
1845 Returns a random value in the range 0.0 &lt;= x &lt; 1.0
1846 </para>
1847 <para>
1848 <literal>random()</literal>
1849 <returnvalue>0.897124072839091</returnvalue>
1850 </para></entry>
1851 </row>
1853 <row>
1854 <entry role="func_table_entry"><para role="func_signature">
1855 <indexterm>
1856 <primary>random_normal</primary>
1857 </indexterm>
1859 <function>random_normal</function> (
1860 <optional> <parameter>mean</parameter> <type>double precision</type>
1861 <optional>, <parameter>stddev</parameter> <type>double precision</type> </optional></optional> )
1862 <returnvalue>double precision</returnvalue>
1863 </para>
1864 <para>
1865 Returns a random value from the normal distribution with the given
1866 parameters; <parameter>mean</parameter> defaults to 0.0
1867 and <parameter>stddev</parameter> defaults to 1.0
1868 </para>
1869 <para>
1870 <literal>random_normal(0.0, 1.0)</literal>
1871 <returnvalue>0.051285419</returnvalue>
1872 </para></entry>
1873 </row>
1875 <row>
1876 <entry role="func_table_entry"><para role="func_signature">
1877 <indexterm>
1878 <primary>setseed</primary>
1879 </indexterm>
1880 <function>setseed</function> ( <type>double precision</type> )
1881 <returnvalue>void</returnvalue>
1882 </para>
1883 <para>
1884 Sets the seed for subsequent <literal>random()</literal> and
1885 <literal>random_normal()</literal> calls;
1886 argument must be between -1.0 and 1.0, inclusive
1887 </para>
1888 <para>
1889 <literal>setseed(0.12345)</literal>
1890 </para></entry>
1891 </row>
1892 </tbody>
1893 </tgroup>
1894 </table>
1896 <para>
1897 The <function>random()</function> function uses a deterministic
1898 pseudo-random number generator.
1899 It is fast but not suitable for cryptographic
1900 applications; see the <xref linkend="pgcrypto"/> module for a more
1901 secure alternative.
1902 If <function>setseed()</function> is called, the series of results of
1903 subsequent <function>random()</function> calls in the current session
1904 can be repeated by re-issuing <function>setseed()</function> with the same
1905 argument.
1906 Without any prior <function>setseed()</function> call in the same
1907 session, the first <function>random()</function> call obtains a seed
1908 from a platform-dependent source of random bits.
1909 These remarks hold equally for <function>random_normal()</function>.
1910 </para>
1912 <para>
1913 <xref linkend="functions-math-trig-table"/> shows the
1914 available trigonometric functions. Each of these functions comes in
1915 two variants, one that measures angles in radians and one that
1916 measures angles in degrees.
1917 </para>
1919 <table id="functions-math-trig-table">
1920 <title>Trigonometric Functions</title>
1922 <tgroup cols="1">
1923 <thead>
1924 <row>
1925 <entry role="func_table_entry"><para role="func_signature">
1926 Function
1927 </para>
1928 <para>
1929 Description
1930 </para>
1931 <para>
1932 Example(s)
1933 </para></entry>
1934 </row>
1935 </thead>
1937 <tbody>
1938 <row>
1939 <entry role="func_table_entry"><para role="func_signature">
1940 <indexterm>
1941 <primary>acos</primary>
1942 </indexterm>
1943 <function>acos</function> ( <type>double precision</type> )
1944 <returnvalue>double precision</returnvalue>
1945 </para>
1946 <para>
1947 Inverse cosine, result in radians
1948 </para>
1949 <para>
1950 <literal>acos(1)</literal>
1951 <returnvalue>0</returnvalue>
1952 </para></entry>
1953 </row>
1955 <row>
1956 <entry role="func_table_entry"><para role="func_signature">
1957 <indexterm>
1958 <primary>acosd</primary>
1959 </indexterm>
1960 <function>acosd</function> ( <type>double precision</type> )
1961 <returnvalue>double precision</returnvalue>
1962 </para>
1963 <para>
1964 Inverse cosine, result in degrees
1965 </para>
1966 <para>
1967 <literal>acosd(0.5)</literal>
1968 <returnvalue>60</returnvalue>
1969 </para></entry>
1970 </row>
1972 <row>
1973 <entry role="func_table_entry"><para role="func_signature">
1974 <indexterm>
1975 <primary>asin</primary>
1976 </indexterm>
1977 <function>asin</function> ( <type>double precision</type> )
1978 <returnvalue>double precision</returnvalue>
1979 </para>
1980 <para>
1981 Inverse sine, result in radians
1982 </para>
1983 <para>
1984 <literal>asin(1)</literal>
1985 <returnvalue>1.5707963267948966</returnvalue>
1986 </para></entry>
1987 </row>
1989 <row>
1990 <entry role="func_table_entry"><para role="func_signature">
1991 <indexterm>
1992 <primary>asind</primary>
1993 </indexterm>
1994 <function>asind</function> ( <type>double precision</type> )
1995 <returnvalue>double precision</returnvalue>
1996 </para>
1997 <para>
1998 Inverse sine, result in degrees
1999 </para>
2000 <para>
2001 <literal>asind(0.5)</literal>
2002 <returnvalue>30</returnvalue>
2003 </para></entry>
2004 </row>
2006 <row>
2007 <entry role="func_table_entry"><para role="func_signature">
2008 <indexterm>
2009 <primary>atan</primary>
2010 </indexterm>
2011 <function>atan</function> ( <type>double precision</type> )
2012 <returnvalue>double precision</returnvalue>
2013 </para>
2014 <para>
2015 Inverse tangent, result in radians
2016 </para>
2017 <para>
2018 <literal>atan(1)</literal>
2019 <returnvalue>0.7853981633974483</returnvalue>
2020 </para></entry>
2021 </row>
2023 <row>
2024 <entry role="func_table_entry"><para role="func_signature">
2025 <indexterm>
2026 <primary>atand</primary>
2027 </indexterm>
2028 <function>atand</function> ( <type>double precision</type> )
2029 <returnvalue>double precision</returnvalue>
2030 </para>
2031 <para>
2032 Inverse tangent, result in degrees
2033 </para>
2034 <para>
2035 <literal>atand(1)</literal>
2036 <returnvalue>45</returnvalue>
2037 </para></entry>
2038 </row>
2040 <row>
2041 <entry role="func_table_entry"><para role="func_signature">
2042 <indexterm>
2043 <primary>atan2</primary>
2044 </indexterm>
2045 <function>atan2</function> ( <parameter>y</parameter> <type>double precision</type>,
2046 <parameter>x</parameter> <type>double precision</type> )
2047 <returnvalue>double precision</returnvalue>
2048 </para>
2049 <para>
2050 Inverse tangent of
2051 <parameter>y</parameter>/<parameter>x</parameter>,
2052 result in radians
2053 </para>
2054 <para>
2055 <literal>atan2(1, 0)</literal>
2056 <returnvalue>1.5707963267948966</returnvalue>
2057 </para></entry>
2058 </row>
2060 <row>
2061 <entry role="func_table_entry"><para role="func_signature">
2062 <indexterm>
2063 <primary>atan2d</primary>
2064 </indexterm>
2065 <function>atan2d</function> ( <parameter>y</parameter> <type>double precision</type>,
2066 <parameter>x</parameter> <type>double precision</type> )
2067 <returnvalue>double precision</returnvalue>
2068 </para>
2069 <para>
2070 Inverse tangent of
2071 <parameter>y</parameter>/<parameter>x</parameter>,
2072 result in degrees
2073 </para>
2074 <para>
2075 <literal>atan2d(1, 0)</literal>
2076 <returnvalue>90</returnvalue>
2077 </para></entry>
2078 </row>
2080 <row>
2081 <entry role="func_table_entry"><para role="func_signature">
2082 <indexterm>
2083 <primary>cos</primary>
2084 </indexterm>
2085 <function>cos</function> ( <type>double precision</type> )
2086 <returnvalue>double precision</returnvalue>
2087 </para>
2088 <para>
2089 Cosine, argument in radians
2090 </para>
2091 <para>
2092 <literal>cos(0)</literal>
2093 <returnvalue>1</returnvalue>
2094 </para></entry>
2095 </row>
2097 <row>
2098 <entry role="func_table_entry"><para role="func_signature">
2099 <indexterm>
2100 <primary>cosd</primary>
2101 </indexterm>
2102 <function>cosd</function> ( <type>double precision</type> )
2103 <returnvalue>double precision</returnvalue>
2104 </para>
2105 <para>
2106 Cosine, argument in degrees
2107 </para>
2108 <para>
2109 <literal>cosd(60)</literal>
2110 <returnvalue>0.5</returnvalue>
2111 </para></entry>
2112 </row>
2114 <row>
2115 <entry role="func_table_entry"><para role="func_signature">
2116 <indexterm>
2117 <primary>cot</primary>
2118 </indexterm>
2119 <function>cot</function> ( <type>double precision</type> )
2120 <returnvalue>double precision</returnvalue>
2121 </para>
2122 <para>
2123 Cotangent, argument in radians
2124 </para>
2125 <para>
2126 <literal>cot(0.5)</literal>
2127 <returnvalue>1.830487721712452</returnvalue>
2128 </para></entry>
2129 </row>
2131 <row>
2132 <entry role="func_table_entry"><para role="func_signature">
2133 <indexterm>
2134 <primary>cotd</primary>
2135 </indexterm>
2136 <function>cotd</function> ( <type>double precision</type> )
2137 <returnvalue>double precision</returnvalue>
2138 </para>
2139 <para>
2140 Cotangent, argument in degrees
2141 </para>
2142 <para>
2143 <literal>cotd(45)</literal>
2144 <returnvalue>1</returnvalue>
2145 </para></entry>
2146 </row>
2148 <row>
2149 <entry role="func_table_entry"><para role="func_signature">
2150 <indexterm>
2151 <primary>sin</primary>
2152 </indexterm>
2153 <function>sin</function> ( <type>double precision</type> )
2154 <returnvalue>double precision</returnvalue>
2155 </para>
2156 <para>
2157 Sine, argument in radians
2158 </para>
2159 <para>
2160 <literal>sin(1)</literal>
2161 <returnvalue>0.8414709848078965</returnvalue>
2162 </para></entry>
2163 </row>
2165 <row>
2166 <entry role="func_table_entry"><para role="func_signature">
2167 <indexterm>
2168 <primary>sind</primary>
2169 </indexterm>
2170 <function>sind</function> ( <type>double precision</type> )
2171 <returnvalue>double precision</returnvalue>
2172 </para>
2173 <para>
2174 Sine, argument in degrees
2175 </para>
2176 <para>
2177 <literal>sind(30)</literal>
2178 <returnvalue>0.5</returnvalue>
2179 </para></entry>
2180 </row>
2182 <row>
2183 <entry role="func_table_entry"><para role="func_signature">
2184 <indexterm>
2185 <primary>tan</primary>
2186 </indexterm>
2187 <function>tan</function> ( <type>double precision</type> )
2188 <returnvalue>double precision</returnvalue>
2189 </para>
2190 <para>
2191 Tangent, argument in radians
2192 </para>
2193 <para>
2194 <literal>tan(1)</literal>
2195 <returnvalue>1.5574077246549023</returnvalue>
2196 </para></entry>
2197 </row>
2199 <row>
2200 <entry role="func_table_entry"><para role="func_signature">
2201 <indexterm>
2202 <primary>tand</primary>
2203 </indexterm>
2204 <function>tand</function> ( <type>double precision</type> )
2205 <returnvalue>double precision</returnvalue>
2206 </para>
2207 <para>
2208 Tangent, argument in degrees
2209 </para>
2210 <para>
2211 <literal>tand(45)</literal>
2212 <returnvalue>1</returnvalue>
2213 </para></entry>
2214 </row>
2215 </tbody>
2216 </tgroup>
2217 </table>
2219 <note>
2220 <para>
2221 Another way to work with angles measured in degrees is to use the unit
2222 transformation functions <literal><function>radians()</function></literal>
2223 and <literal><function>degrees()</function></literal> shown earlier.
2224 However, using the degree-based trigonometric functions is preferred,
2225 as that way avoids round-off error for special cases such
2226 as <literal>sind(30)</literal>.
2227 </para>
2228 </note>
2230 <para>
2231 <xref linkend="functions-math-hyp-table"/> shows the
2232 available hyperbolic functions.
2233 </para>
2235 <table id="functions-math-hyp-table">
2236 <title>Hyperbolic Functions</title>
2238 <tgroup cols="1">
2239 <thead>
2240 <row>
2241 <entry role="func_table_entry"><para role="func_signature">
2242 Function
2243 </para>
2244 <para>
2245 Description
2246 </para>
2247 <para>
2248 Example(s)
2249 </para></entry>
2250 </row>
2251 </thead>
2253 <tbody>
2254 <row>
2255 <entry role="func_table_entry"><para role="func_signature">
2256 <indexterm>
2257 <primary>sinh</primary>
2258 </indexterm>
2259 <function>sinh</function> ( <type>double precision</type> )
2260 <returnvalue>double precision</returnvalue>
2261 </para>
2262 <para>
2263 Hyperbolic sine
2264 </para>
2265 <para>
2266 <literal>sinh(1)</literal>
2267 <returnvalue>1.1752011936438014</returnvalue>
2268 </para></entry>
2269 </row>
2271 <row>
2272 <entry role="func_table_entry"><para role="func_signature">
2273 <indexterm>
2274 <primary>cosh</primary>
2275 </indexterm>
2276 <function>cosh</function> ( <type>double precision</type> )
2277 <returnvalue>double precision</returnvalue>
2278 </para>
2279 <para>
2280 Hyperbolic cosine
2281 </para>
2282 <para>
2283 <literal>cosh(0)</literal>
2284 <returnvalue>1</returnvalue>
2285 </para></entry>
2286 </row>
2288 <row>
2289 <entry role="func_table_entry"><para role="func_signature">
2290 <indexterm>
2291 <primary>tanh</primary>
2292 </indexterm>
2293 <function>tanh</function> ( <type>double precision</type> )
2294 <returnvalue>double precision</returnvalue>
2295 </para>
2296 <para>
2297 Hyperbolic tangent
2298 </para>
2299 <para>
2300 <literal>tanh(1)</literal>
2301 <returnvalue>0.7615941559557649</returnvalue>
2302 </para></entry>
2303 </row>
2305 <row>
2306 <entry role="func_table_entry"><para role="func_signature">
2307 <indexterm>
2308 <primary>asinh</primary>
2309 </indexterm>
2310 <function>asinh</function> ( <type>double precision</type> )
2311 <returnvalue>double precision</returnvalue>
2312 </para>
2313 <para>
2314 Inverse hyperbolic sine
2315 </para>
2316 <para>
2317 <literal>asinh(1)</literal>
2318 <returnvalue>0.881373587019543</returnvalue>
2319 </para></entry>
2320 </row>
2322 <row>
2323 <entry role="func_table_entry"><para role="func_signature">
2324 <indexterm>
2325 <primary>acosh</primary>
2326 </indexterm>
2327 <function>acosh</function> ( <type>double precision</type> )
2328 <returnvalue>double precision</returnvalue>
2329 </para>
2330 <para>
2331 Inverse hyperbolic cosine
2332 </para>
2333 <para>
2334 <literal>acosh(1)</literal>
2335 <returnvalue>0</returnvalue>
2336 </para></entry>
2337 </row>
2339 <row>
2340 <entry role="func_table_entry"><para role="func_signature">
2341 <indexterm>
2342 <primary>atanh</primary>
2343 </indexterm>
2344 <function>atanh</function> ( <type>double precision</type> )
2345 <returnvalue>double precision</returnvalue>
2346 </para>
2347 <para>
2348 Inverse hyperbolic tangent
2349 </para>
2350 <para>
2351 <literal>atanh(0.5)</literal>
2352 <returnvalue>0.5493061443340548</returnvalue>
2353 </para></entry>
2354 </row>
2355 </tbody>
2356 </tgroup>
2357 </table>
2359 </sect1>
2362 <sect1 id="functions-string">
2363 <title>String Functions and Operators</title>
2365 <para>
2366 This section describes functions and operators for examining and
2367 manipulating string values. Strings in this context include values
2368 of the types <type>character</type>, <type>character varying</type>,
2369 and <type>text</type>. Except where noted, these functions and operators
2370 are declared to accept and return type <type>text</type>. They will
2371 interchangeably accept <type>character varying</type> arguments.
2372 Values of type <type>character</type> will be converted
2373 to <type>text</type> before the function or operator is applied, resulting
2374 in stripping any trailing spaces in the <type>character</type> value.
2375 </para>
2377 <para>
2378 <acronym>SQL</acronym> defines some string functions that use
2379 key words, rather than commas, to separate
2380 arguments. Details are in
2381 <xref linkend="functions-string-sql"/>.
2382 <productname>PostgreSQL</productname> also provides versions of these functions
2383 that use the regular function invocation syntax
2384 (see <xref linkend="functions-string-other"/>).
2385 </para>
2387 <note>
2388 <para>
2389 The string concatenation operator (<literal>||</literal>) will accept
2390 non-string input, so long as at least one input is of string type, as shown
2391 in <xref linkend="functions-string-sql"/>. For other cases, inserting an
2392 explicit coercion to <type>text</type> can be used to have non-string input
2393 accepted.
2394 </para>
2395 </note>
2397 <table id="functions-string-sql">
2398 <title><acronym>SQL</acronym> String Functions and Operators</title>
2399 <tgroup cols="1">
2400 <thead>
2401 <row>
2402 <entry role="func_table_entry"><para role="func_signature">
2403 Function/Operator
2404 </para>
2405 <para>
2406 Description
2407 </para>
2408 <para>
2409 Example(s)
2410 </para></entry>
2411 </row>
2412 </thead>
2414 <tbody>
2415 <row>
2416 <entry role="func_table_entry"><para role="func_signature">
2417 <indexterm>
2418 <primary>character string</primary>
2419 <secondary>concatenation</secondary>
2420 </indexterm>
2421 <type>text</type> <literal>||</literal> <type>text</type>
2422 <returnvalue>text</returnvalue>
2423 </para>
2424 <para>
2425 Concatenates the two strings.
2426 </para>
2427 <para>
2428 <literal>'Post' || 'greSQL'</literal>
2429 <returnvalue>PostgreSQL</returnvalue>
2430 </para></entry>
2431 </row>
2433 <row>
2434 <entry role="func_table_entry"><para role="func_signature">
2435 <type>text</type> <literal>||</literal> <type>anynonarray</type>
2436 <returnvalue>text</returnvalue>
2437 </para>
2438 <para role="func_signature">
2439 <type>anynonarray</type> <literal>||</literal> <type>text</type>
2440 <returnvalue>text</returnvalue>
2441 </para>
2442 <para>
2443 Converts the non-string input to text, then concatenates the two
2444 strings. (The non-string input cannot be of an array type, because
2445 that would create ambiguity with the array <literal>||</literal>
2446 operators. If you want to concatenate an array's text equivalent,
2447 cast it to <type>text</type> explicitly.)
2448 </para>
2449 <para>
2450 <literal>'Value: ' || 42</literal>
2451 <returnvalue>Value: 42</returnvalue>
2452 </para></entry>
2453 </row>
2455 <row>
2456 <entry role="func_table_entry"><para role="func_signature">
2457 <indexterm>
2458 <primary>btrim</primary>
2459 </indexterm>
2460 <function>btrim</function> ( <parameter>string</parameter> <type>text</type>
2461 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2462 <returnvalue>text</returnvalue>
2463 </para>
2464 <para>
2465 Removes the longest string containing only characters
2466 in <parameter>characters</parameter> (a space by default)
2467 from the start and end of <parameter>string</parameter>.
2468 </para>
2469 <para>
2470 <literal>btrim('xyxtrimyyx', 'xyz')</literal>
2471 <returnvalue>trim</returnvalue>
2472 </para></entry>
2473 </row>
2475 <row>
2476 <entry role="func_table_entry"><para role="func_signature">
2477 <indexterm>
2478 <primary>normalized</primary>
2479 </indexterm>
2480 <indexterm>
2481 <primary>Unicode normalization</primary>
2482 </indexterm>
2483 <type>text</type> <literal>IS</literal> <optional><literal>NOT</literal></optional> <optional><parameter>form</parameter></optional> <literal>NORMALIZED</literal>
2484 <returnvalue>boolean</returnvalue>
2485 </para>
2486 <para>
2487 Checks whether the string is in the specified Unicode normalization
2488 form. The optional <parameter>form</parameter> key word specifies the
2489 form: <literal>NFC</literal> (the default), <literal>NFD</literal>,
2490 <literal>NFKC</literal>, or <literal>NFKD</literal>. This expression can
2491 only be used when the server encoding is <literal>UTF8</literal>. Note
2492 that checking for normalization using this expression is often faster
2493 than normalizing possibly already normalized strings.
2494 </para>
2495 <para>
2496 <literal>U&amp;'\0061\0308bc' IS NFD NORMALIZED</literal>
2497 <returnvalue>t</returnvalue>
2498 </para></entry>
2499 </row>
2501 <row>
2502 <entry role="func_table_entry"><para role="func_signature">
2503 <indexterm>
2504 <primary>bit_length</primary>
2505 </indexterm>
2506 <function>bit_length</function> ( <type>text</type> )
2507 <returnvalue>integer</returnvalue>
2508 </para>
2509 <para>
2510 Returns number of bits in the string (8
2511 times the <function>octet_length</function>).
2512 </para>
2513 <para>
2514 <literal>bit_length('jose')</literal>
2515 <returnvalue>32</returnvalue>
2516 </para></entry>
2517 </row>
2519 <row>
2520 <entry role="func_table_entry"><para role="func_signature">
2521 <indexterm>
2522 <primary>char_length</primary>
2523 </indexterm>
2524 <indexterm>
2525 <primary>character string</primary>
2526 <secondary>length</secondary>
2527 </indexterm>
2528 <indexterm>
2529 <primary>length</primary>
2530 <secondary sortas="character string">of a character string</secondary>
2531 <see>character string, length</see>
2532 </indexterm>
2533 <function>char_length</function> ( <type>text</type> )
2534 <returnvalue>integer</returnvalue>
2535 </para>
2536 <para role="func_signature">
2537 <indexterm>
2538 <primary>character_length</primary>
2539 </indexterm>
2540 <function>character_length</function> ( <type>text</type> )
2541 <returnvalue>integer</returnvalue>
2542 </para>
2543 <para>
2544 Returns number of characters in the string.
2545 </para>
2546 <para>
2547 <literal>char_length('jos&eacute;')</literal>
2548 <returnvalue>4</returnvalue>
2549 </para></entry>
2550 </row>
2552 <row>
2553 <entry role="func_table_entry"><para role="func_signature">
2554 <indexterm>
2555 <primary>lower</primary>
2556 </indexterm>
2557 <function>lower</function> ( <type>text</type> )
2558 <returnvalue>text</returnvalue>
2559 </para>
2560 <para>
2561 Converts the string to all lower case, according to the rules of the
2562 database's locale.
2563 </para>
2564 <para>
2565 <literal>lower('TOM')</literal>
2566 <returnvalue>tom</returnvalue>
2567 </para></entry>
2568 </row>
2570 <row>
2571 <entry role="func_table_entry"><para role="func_signature">
2572 <indexterm>
2573 <primary>lpad</primary>
2574 </indexterm>
2575 <function>lpad</function> ( <parameter>string</parameter> <type>text</type>,
2576 <parameter>length</parameter> <type>integer</type>
2577 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
2578 <returnvalue>text</returnvalue>
2579 </para>
2580 <para>
2581 Extends the <parameter>string</parameter> to length
2582 <parameter>length</parameter> by prepending the characters
2583 <parameter>fill</parameter> (a space by default). If the
2584 <parameter>string</parameter> is already longer than
2585 <parameter>length</parameter> then it is truncated (on the right).
2586 </para>
2587 <para>
2588 <literal>lpad('hi', 5, 'xy')</literal>
2589 <returnvalue>xyxhi</returnvalue>
2590 </para></entry>
2591 </row>
2593 <row>
2594 <entry role="func_table_entry"><para role="func_signature">
2595 <indexterm>
2596 <primary>ltrim</primary>
2597 </indexterm>
2598 <function>ltrim</function> ( <parameter>string</parameter> <type>text</type>
2599 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2600 <returnvalue>text</returnvalue>
2601 </para>
2602 <para>
2603 Removes the longest string containing only characters in
2604 <parameter>characters</parameter> (a space by default) from the start of
2605 <parameter>string</parameter>.
2606 </para>
2607 <para>
2608 <literal>ltrim('zzzytest', 'xyz')</literal>
2609 <returnvalue>test</returnvalue>
2610 </para></entry>
2611 </row>
2613 <row>
2614 <entry role="func_table_entry"><para role="func_signature">
2615 <indexterm>
2616 <primary>normalize</primary>
2617 </indexterm>
2618 <indexterm>
2619 <primary>Unicode normalization</primary>
2620 </indexterm>
2621 <function>normalize</function> ( <type>text</type>
2622 <optional>, <parameter>form</parameter> </optional> )
2623 <returnvalue>text</returnvalue>
2624 </para>
2625 <para>
2626 Converts the string to the specified Unicode
2627 normalization form. The optional <parameter>form</parameter> key word
2628 specifies the form: <literal>NFC</literal> (the default),
2629 <literal>NFD</literal>, <literal>NFKC</literal>, or
2630 <literal>NFKD</literal>. This function can only be used when the
2631 server encoding is <literal>UTF8</literal>.
2632 </para>
2633 <para>
2634 <literal>normalize(U&amp;'\0061\0308bc', NFC)</literal>
2635 <returnvalue>U&amp;'\00E4bc'</returnvalue>
2636 </para></entry>
2637 </row>
2639 <row>
2640 <entry role="func_table_entry"><para role="func_signature">
2641 <indexterm>
2642 <primary>octet_length</primary>
2643 </indexterm>
2644 <function>octet_length</function> ( <type>text</type> )
2645 <returnvalue>integer</returnvalue>
2646 </para>
2647 <para>
2648 Returns number of bytes in the string.
2649 </para>
2650 <para>
2651 <literal>octet_length('jos&eacute;')</literal>
2652 <returnvalue>5</returnvalue> (if server encoding is UTF8)
2653 </para></entry>
2654 </row>
2656 <row>
2657 <entry role="func_table_entry"><para role="func_signature">
2658 <indexterm>
2659 <primary>octet_length</primary>
2660 </indexterm>
2661 <function>octet_length</function> ( <type>character</type> )
2662 <returnvalue>integer</returnvalue>
2663 </para>
2664 <para>
2665 Returns number of bytes in the string. Since this version of the
2666 function accepts type <type>character</type> directly, it will not
2667 strip trailing spaces.
2668 </para>
2669 <para>
2670 <literal>octet_length('abc '::character(4))</literal>
2671 <returnvalue>4</returnvalue>
2672 </para></entry>
2673 </row>
2675 <row>
2676 <entry role="func_table_entry"><para role="func_signature">
2677 <indexterm>
2678 <primary>overlay</primary>
2679 </indexterm>
2680 <function>overlay</function> ( <parameter>string</parameter> <type>text</type> <literal>PLACING</literal> <parameter>newsubstring</parameter> <type>text</type> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> )
2681 <returnvalue>text</returnvalue>
2682 </para>
2683 <para>
2684 Replaces the substring of <parameter>string</parameter> that starts at
2685 the <parameter>start</parameter>'th character and extends
2686 for <parameter>count</parameter> characters
2687 with <parameter>newsubstring</parameter>.
2688 If <parameter>count</parameter> is omitted, it defaults to the length
2689 of <parameter>newsubstring</parameter>.
2690 </para>
2691 <para>
2692 <literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal>
2693 <returnvalue>Thomas</returnvalue>
2694 </para></entry>
2695 </row>
2697 <row>
2698 <entry role="func_table_entry"><para role="func_signature">
2699 <indexterm>
2700 <primary>position</primary>
2701 </indexterm>
2702 <function>position</function> ( <parameter>substring</parameter> <type>text</type> <literal>IN</literal> <parameter>string</parameter> <type>text</type> )
2703 <returnvalue>integer</returnvalue>
2704 </para>
2705 <para>
2706 Returns first starting index of the specified
2707 <parameter>substring</parameter> within
2708 <parameter>string</parameter>, or zero if it's not present.
2709 </para>
2710 <para>
2711 <literal>position('om' in 'Thomas')</literal>
2712 <returnvalue>3</returnvalue>
2713 </para></entry>
2714 </row>
2716 <row>
2717 <entry role="func_table_entry"><para role="func_signature">
2718 <indexterm>
2719 <primary>rpad</primary>
2720 </indexterm>
2721 <function>rpad</function> ( <parameter>string</parameter> <type>text</type>,
2722 <parameter>length</parameter> <type>integer</type>
2723 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
2724 <returnvalue>text</returnvalue>
2725 </para>
2726 <para>
2727 Extends the <parameter>string</parameter> to length
2728 <parameter>length</parameter> by appending the characters
2729 <parameter>fill</parameter> (a space by default). If the
2730 <parameter>string</parameter> is already longer than
2731 <parameter>length</parameter> then it is truncated.
2732 </para>
2733 <para>
2734 <literal>rpad('hi', 5, 'xy')</literal>
2735 <returnvalue>hixyx</returnvalue>
2736 </para></entry>
2737 </row>
2739 <row>
2740 <entry role="func_table_entry"><para role="func_signature">
2741 <indexterm>
2742 <primary>rtrim</primary>
2743 </indexterm>
2744 <function>rtrim</function> ( <parameter>string</parameter> <type>text</type>
2745 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2746 <returnvalue>text</returnvalue>
2747 </para>
2748 <para>
2749 Removes the longest string containing only characters in
2750 <parameter>characters</parameter> (a space by default) from the end of
2751 <parameter>string</parameter>.
2752 </para>
2753 <para>
2754 <literal>rtrim('testxxzx', 'xyz')</literal>
2755 <returnvalue>test</returnvalue>
2756 </para></entry>
2757 </row>
2759 <row>
2760 <entry role="func_table_entry"><para role="func_signature">
2761 <indexterm>
2762 <primary>substring</primary>
2763 </indexterm>
2764 <function>substring</function> ( <parameter>string</parameter> <type>text</type> <optional> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> </optional> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> )
2765 <returnvalue>text</returnvalue>
2766 </para>
2767 <para>
2768 Extracts the substring of <parameter>string</parameter> starting at
2769 the <parameter>start</parameter>'th character if that is specified,
2770 and stopping after <parameter>count</parameter> characters if that is
2771 specified. Provide at least one of <parameter>start</parameter>
2772 and <parameter>count</parameter>.
2773 </para>
2774 <para>
2775 <literal>substring('Thomas' from 2 for 3)</literal>
2776 <returnvalue>hom</returnvalue>
2777 </para>
2778 <para>
2779 <literal>substring('Thomas' from 3)</literal>
2780 <returnvalue>omas</returnvalue>
2781 </para>
2782 <para>
2783 <literal>substring('Thomas' for 2)</literal>
2784 <returnvalue>Th</returnvalue>
2785 </para></entry>
2786 </row>
2788 <row>
2789 <entry role="func_table_entry"><para role="func_signature">
2790 <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>FROM</literal> <parameter>pattern</parameter> <type>text</type> )
2791 <returnvalue>text</returnvalue>
2792 </para>
2793 <para>
2794 Extracts the first substring matching POSIX regular expression; see
2795 <xref linkend="functions-posix-regexp"/>.
2796 </para>
2797 <para>
2798 <literal>substring('Thomas' from '...$')</literal>
2799 <returnvalue>mas</returnvalue>
2800 </para></entry>
2801 </row>
2803 <row>
2804 <entry role="func_table_entry"><para role="func_signature">
2805 <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>SIMILAR</literal> <parameter>pattern</parameter> <type>text</type> <literal>ESCAPE</literal> <parameter>escape</parameter> <type>text</type> )
2806 <returnvalue>text</returnvalue>
2807 </para>
2808 <para role="func_signature">
2809 <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>FROM</literal> <parameter>pattern</parameter> <type>text</type> <literal>FOR</literal> <parameter>escape</parameter> <type>text</type> )
2810 <returnvalue>text</returnvalue>
2811 </para>
2812 <para>
2813 Extracts the first substring matching <acronym>SQL</acronym> regular expression;
2814 see <xref linkend="functions-similarto-regexp"/>. The first form has
2815 been specified since SQL:2003; the second form was only in SQL:1999
2816 and should be considered obsolete.
2817 </para>
2818 <para>
2819 <literal>substring('Thomas' similar '%#"o_a#"_' escape '#')</literal>
2820 <returnvalue>oma</returnvalue>
2821 </para></entry>
2822 </row>
2824 <row>
2825 <entry role="func_table_entry"><para role="func_signature">
2826 <indexterm>
2827 <primary>trim</primary>
2828 </indexterm>
2829 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
2830 <optional> <parameter>characters</parameter> <type>text</type> </optional> <literal>FROM</literal>
2831 <parameter>string</parameter> <type>text</type> )
2832 <returnvalue>text</returnvalue>
2833 </para>
2834 <para>
2835 Removes the longest string containing only characters in
2836 <parameter>characters</parameter> (a space by default) from the
2837 start, end, or both ends (<literal>BOTH</literal> is the default)
2838 of <parameter>string</parameter>.
2839 </para>
2840 <para>
2841 <literal>trim(both 'xyz' from 'yxTomxx')</literal>
2842 <returnvalue>Tom</returnvalue>
2843 </para></entry>
2844 </row>
2846 <row>
2847 <entry role="func_table_entry"><para role="func_signature">
2848 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
2849 <parameter>string</parameter> <type>text</type> <optional>,
2850 <parameter>characters</parameter> <type>text</type> </optional> )
2851 <returnvalue>text</returnvalue>
2852 </para>
2853 <para>
2854 This is a non-standard syntax for <function>trim()</function>.
2855 </para>
2856 <para>
2857 <literal>trim(both from 'yxTomxx', 'xyz')</literal>
2858 <returnvalue>Tom</returnvalue>
2859 </para></entry>
2860 </row>
2862 <row>
2863 <entry role="func_table_entry"><para role="func_signature">
2864 <indexterm>
2865 <primary>upper</primary>
2866 </indexterm>
2867 <function>upper</function> ( <type>text</type> )
2868 <returnvalue>text</returnvalue>
2869 </para>
2870 <para>
2871 Converts the string to all upper case, according to the rules of the
2872 database's locale.
2873 </para>
2874 <para>
2875 <literal>upper('tom')</literal>
2876 <returnvalue>TOM</returnvalue>
2877 </para></entry>
2878 </row>
2879 </tbody>
2880 </tgroup>
2881 </table>
2883 <para>
2884 Additional string manipulation functions and operators are available
2885 and are listed in <xref linkend="functions-string-other"/>. (Some of
2886 these are used internally to implement
2887 the <acronym>SQL</acronym>-standard string functions listed in
2888 <xref linkend="functions-string-sql"/>.)
2889 There are also pattern-matching operators, which are described in
2890 <xref linkend="functions-matching"/>, and operators for full-text
2891 search, which are described in <xref linkend="textsearch"/>.
2892 </para>
2894 <table id="functions-string-other">
2895 <title>Other String Functions and Operators</title>
2896 <tgroup cols="1">
2897 <thead>
2898 <row>
2899 <entry role="func_table_entry"><para role="func_signature">
2900 Function/Operator
2901 </para>
2902 <para>
2903 Description
2904 </para>
2905 <para>
2906 Example(s)
2907 </para></entry>
2908 </row>
2909 </thead>
2911 <tbody>
2912 <row>
2913 <entry role="func_table_entry"><para role="func_signature">
2914 <indexterm>
2915 <primary>character string</primary>
2916 <secondary>prefix test</secondary>
2917 </indexterm>
2918 <type>text</type> <literal>^@</literal> <type>text</type>
2919 <returnvalue>boolean</returnvalue>
2920 </para>
2921 <para>
2922 Returns true if the first string starts with the second string
2923 (equivalent to the <function>starts_with()</function> function).
2924 </para>
2925 <para>
2926 <literal>'alphabet' ^@ 'alph'</literal>
2927 <returnvalue>t</returnvalue>
2928 </para></entry>
2929 </row>
2931 <row>
2932 <entry role="func_table_entry"><para role="func_signature">
2933 <indexterm>
2934 <primary>ascii</primary>
2935 </indexterm>
2936 <function>ascii</function> ( <type>text</type> )
2937 <returnvalue>integer</returnvalue>
2938 </para>
2939 <para>
2940 Returns the numeric code of the first character of the argument.
2941 In <acronym>UTF8</acronym> encoding, returns the Unicode code point
2942 of the character. In other multibyte encodings, the argument must
2943 be an <acronym>ASCII</acronym> character.
2944 </para>
2945 <para>
2946 <literal>ascii('x')</literal>
2947 <returnvalue>120</returnvalue>
2948 </para></entry>
2949 </row>
2951 <row>
2952 <entry role="func_table_entry"><para role="func_signature">
2953 <indexterm>
2954 <primary>chr</primary>
2955 </indexterm>
2956 <function>chr</function> ( <type>integer</type> )
2957 <returnvalue>text</returnvalue>
2958 </para>
2959 <para>
2960 Returns the character with the given code. In <acronym>UTF8</acronym>
2961 encoding the argument is treated as a Unicode code point. In other
2962 multibyte encodings the argument must designate
2963 an <acronym>ASCII</acronym> character. <literal>chr(0)</literal> is
2964 disallowed because text data types cannot store that character.
2965 </para>
2966 <para>
2967 <literal>chr(65)</literal>
2968 <returnvalue>A</returnvalue>
2969 </para></entry>
2970 </row>
2972 <row>
2973 <entry role="func_table_entry"><para role="func_signature">
2974 <indexterm>
2975 <primary>concat</primary>
2976 </indexterm>
2977 <function>concat</function> ( <parameter>val1</parameter> <type>"any"</type>
2978 [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] )
2979 <returnvalue>text</returnvalue>
2980 </para>
2981 <para>
2982 Concatenates the text representations of all the arguments.
2983 NULL arguments are ignored.
2984 </para>
2985 <para>
2986 <literal>concat('abcde', 2, NULL, 22)</literal>
2987 <returnvalue>abcde222</returnvalue>
2988 </para></entry>
2989 </row>
2991 <row>
2992 <entry role="func_table_entry"><para role="func_signature">
2993 <indexterm>
2994 <primary>concat_ws</primary>
2995 </indexterm>
2996 <function>concat_ws</function> ( <parameter>sep</parameter> <type>text</type>,
2997 <parameter>val1</parameter> <type>"any"</type>
2998 [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] )
2999 <returnvalue>text</returnvalue>
3000 </para>
3001 <para>
3002 Concatenates all but the first argument, with separators. The first
3003 argument is used as the separator string, and should not be NULL.
3004 Other NULL arguments are ignored.
3005 </para>
3006 <para>
3007 <literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal>
3008 <returnvalue>abcde,2,22</returnvalue>
3009 </para></entry>
3010 </row>
3012 <row>
3013 <entry role="func_table_entry"><para role="func_signature">
3014 <indexterm>
3015 <primary>format</primary>
3016 </indexterm>
3017 <function>format</function> ( <parameter>formatstr</parameter> <type>text</type>
3018 [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ] )
3019 <returnvalue>text</returnvalue>
3020 </para>
3021 <para>
3022 Formats arguments according to a format string;
3023 see <xref linkend="functions-string-format"/>.
3024 This function is similar to the C function <function>sprintf</function>.
3025 </para>
3026 <para>
3027 <literal>format('Hello %s, %1$s', 'World')</literal>
3028 <returnvalue>Hello World, World</returnvalue>
3029 </para></entry>
3030 </row>
3032 <row>
3033 <entry role="func_table_entry"><para role="func_signature">
3034 <indexterm>
3035 <primary>initcap</primary>
3036 </indexterm>
3037 <function>initcap</function> ( <type>text</type> )
3038 <returnvalue>text</returnvalue>
3039 </para>
3040 <para>
3041 Converts the first letter of each word to upper case and the
3042 rest to lower case. Words are sequences of alphanumeric
3043 characters separated by non-alphanumeric characters.
3044 </para>
3045 <para>
3046 <literal>initcap('hi THOMAS')</literal>
3047 <returnvalue>Hi Thomas</returnvalue>
3048 </para></entry>
3049 </row>
3051 <row>
3052 <entry role="func_table_entry"><para role="func_signature">
3053 <indexterm>
3054 <primary>left</primary>
3055 </indexterm>
3056 <function>left</function> ( <parameter>string</parameter> <type>text</type>,
3057 <parameter>n</parameter> <type>integer</type> )
3058 <returnvalue>text</returnvalue>
3059 </para>
3060 <para>
3061 Returns first <parameter>n</parameter> characters in the
3062 string, or when <parameter>n</parameter> is negative, returns
3063 all but last |<parameter>n</parameter>| characters.
3064 </para>
3065 <para>
3066 <literal>left('abcde', 2)</literal>
3067 <returnvalue>ab</returnvalue>
3068 </para></entry>
3069 </row>
3071 <row>
3072 <entry role="func_table_entry"><para role="func_signature">
3073 <indexterm>
3074 <primary>length</primary>
3075 </indexterm>
3076 <function>length</function> ( <type>text</type> )
3077 <returnvalue>integer</returnvalue>
3078 </para>
3079 <para>
3080 Returns the number of characters in the string.
3081 </para>
3082 <para>
3083 <literal>length('jose')</literal>
3084 <returnvalue>4</returnvalue>
3085 </para></entry>
3086 </row>
3088 <row>
3089 <entry role="func_table_entry"><para role="func_signature">
3090 <indexterm>
3091 <primary>md5</primary>
3092 </indexterm>
3093 <function>md5</function> ( <type>text</type> )
3094 <returnvalue>text</returnvalue>
3095 </para>
3096 <para>
3097 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
3098 the argument, with the result written in hexadecimal.
3099 </para>
3100 <para>
3101 <literal>md5('abc')</literal>
3102 <returnvalue>900150983cd24fb0&zwsp;d6963f7d28e17f72</returnvalue>
3103 </para></entry>
3104 </row>
3106 <row>
3107 <entry role="func_table_entry"><para role="func_signature">
3108 <indexterm>
3109 <primary>parse_ident</primary>
3110 </indexterm>
3111 <function>parse_ident</function> ( <parameter>qualified_identifier</parameter> <type>text</type>
3112 [, <parameter>strict_mode</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>true</literal> ] )
3113 <returnvalue>text[]</returnvalue>
3114 </para>
3115 <para>
3116 Splits <parameter>qualified_identifier</parameter> into an array of
3117 identifiers, removing any quoting of individual identifiers. By
3118 default, extra characters after the last identifier are considered an
3119 error; but if the second parameter is <literal>false</literal>, then such
3120 extra characters are ignored. (This behavior is useful for parsing
3121 names for objects like functions.) Note that this function does not
3122 truncate over-length identifiers. If you want truncation you can cast
3123 the result to <type>name[]</type>.
3124 </para>
3125 <para>
3126 <literal>parse_ident('"SomeSchema".someTable')</literal>
3127 <returnvalue>{SomeSchema,sometable}</returnvalue>
3128 </para></entry>
3129 </row>
3131 <row>
3132 <entry role="func_table_entry"><para role="func_signature">
3133 <indexterm>
3134 <primary>pg_client_encoding</primary>
3135 </indexterm>
3136 <function>pg_client_encoding</function> ( )
3137 <returnvalue>name</returnvalue>
3138 </para>
3139 <para>
3140 Returns current client encoding name.
3141 </para>
3142 <para>
3143 <literal>pg_client_encoding()</literal>
3144 <returnvalue>UTF8</returnvalue>
3145 </para></entry>
3146 </row>
3148 <row>
3149 <entry role="func_table_entry"><para role="func_signature">
3150 <indexterm>
3151 <primary>quote_ident</primary>
3152 </indexterm>
3153 <function>quote_ident</function> ( <type>text</type> )
3154 <returnvalue>text</returnvalue>
3155 </para>
3156 <para>
3157 Returns the given string suitably quoted to be used as an identifier
3158 in an <acronym>SQL</acronym> statement string.
3159 Quotes are added only if necessary (i.e., if the string contains
3160 non-identifier characters or would be case-folded).
3161 Embedded quotes are properly doubled.
3162 See also <xref linkend="plpgsql-quote-literal-example"/>.
3163 </para>
3164 <para>
3165 <literal>quote_ident('Foo bar')</literal>
3166 <returnvalue>"Foo bar"</returnvalue>
3167 </para></entry>
3168 </row>
3170 <row>
3171 <entry role="func_table_entry"><para role="func_signature">
3172 <indexterm>
3173 <primary>quote_literal</primary>
3174 </indexterm>
3175 <function>quote_literal</function> ( <type>text</type> )
3176 <returnvalue>text</returnvalue>
3177 </para>
3178 <para>
3179 Returns the given string suitably quoted to be used as a string literal
3180 in an <acronym>SQL</acronym> statement string.
3181 Embedded single-quotes and backslashes are properly doubled.
3182 Note that <function>quote_literal</function> returns null on null
3183 input; if the argument might be null,
3184 <function>quote_nullable</function> is often more suitable.
3185 See also <xref linkend="plpgsql-quote-literal-example"/>.
3186 </para>
3187 <para>
3188 <literal>quote_literal(E'O\'Reilly')</literal>
3189 <returnvalue>'O''Reilly'</returnvalue>
3190 </para></entry>
3191 </row>
3193 <row>
3194 <entry role="func_table_entry"><para role="func_signature">
3195 <function>quote_literal</function> ( <type>anyelement</type> )
3196 <returnvalue>text</returnvalue>
3197 </para>
3198 <para>
3199 Converts the given value to text and then quotes it as a literal.
3200 Embedded single-quotes and backslashes are properly doubled.
3201 </para>
3202 <para>
3203 <literal>quote_literal(42.5)</literal>
3204 <returnvalue>'42.5'</returnvalue>
3205 </para></entry>
3206 </row>
3208 <row>
3209 <entry role="func_table_entry"><para role="func_signature">
3210 <indexterm>
3211 <primary>quote_nullable</primary>
3212 </indexterm>
3213 <function>quote_nullable</function> ( <type>text</type> )
3214 <returnvalue>text</returnvalue>
3215 </para>
3216 <para>
3217 Returns the given string suitably quoted to be used as a string literal
3218 in an <acronym>SQL</acronym> statement string; or, if the argument
3219 is null, returns <literal>NULL</literal>.
3220 Embedded single-quotes and backslashes are properly doubled.
3221 See also <xref linkend="plpgsql-quote-literal-example"/>.
3222 </para>
3223 <para>
3224 <literal>quote_nullable(NULL)</literal>
3225 <returnvalue>NULL</returnvalue>
3226 </para></entry>
3227 </row>
3229 <row>
3230 <entry role="func_table_entry"><para role="func_signature">
3231 <function>quote_nullable</function> ( <type>anyelement</type> )
3232 <returnvalue>text</returnvalue>
3233 </para>
3234 <para>
3235 Converts the given value to text and then quotes it as a literal;
3236 or, if the argument is null, returns <literal>NULL</literal>.
3237 Embedded single-quotes and backslashes are properly doubled.
3238 </para>
3239 <para>
3240 <literal>quote_nullable(42.5)</literal>
3241 <returnvalue>'42.5'</returnvalue>
3242 </para></entry>
3243 </row>
3245 <row>
3246 <entry role="func_table_entry"><para role="func_signature">
3247 <indexterm>
3248 <primary>regexp_count</primary>
3249 </indexterm>
3250 <function>regexp_count</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3251 [, <parameter>start</parameter> <type>integer</type>
3252 [, <parameter>flags</parameter> <type>text</type> ] ] )
3253 <returnvalue>integer</returnvalue>
3254 </para>
3255 <para>
3256 Returns the number of times the POSIX regular
3257 expression <parameter>pattern</parameter> matches in
3258 the <parameter>string</parameter>; see
3259 <xref linkend="functions-posix-regexp"/>.
3260 </para>
3261 <para>
3262 <literal>regexp_count('123456789012', '\d\d\d', 2)</literal>
3263 <returnvalue>3</returnvalue>
3264 </para></entry>
3265 </row>
3267 <row>
3268 <entry role="func_table_entry"><para role="func_signature">
3269 <indexterm>
3270 <primary>regexp_instr</primary>
3271 </indexterm>
3272 <function>regexp_instr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3273 [, <parameter>start</parameter> <type>integer</type>
3274 [, <parameter>N</parameter> <type>integer</type>
3275 [, <parameter>endoption</parameter> <type>integer</type>
3276 [, <parameter>flags</parameter> <type>text</type>
3277 [, <parameter>subexpr</parameter> <type>integer</type> ] ] ] ] ] )
3278 <returnvalue>integer</returnvalue>
3279 </para>
3280 <para>
3281 Returns the position within <parameter>string</parameter> where
3282 the <parameter>N</parameter>'th match of the POSIX regular
3283 expression <parameter>pattern</parameter> occurs, or zero if there is
3284 no such match; see <xref linkend="functions-posix-regexp"/>.
3285 </para>
3286 <para>
3287 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i')</literal>
3288 <returnvalue>3</returnvalue>
3289 </para>
3290 <para>
3291 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i', 2)</literal>
3292 <returnvalue>5</returnvalue>
3293 </para></entry>
3294 </row>
3296 <row>
3297 <entry role="func_table_entry"><para role="func_signature">
3298 <indexterm>
3299 <primary>regexp_like</primary>
3300 </indexterm>
3301 <function>regexp_like</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3302 [, <parameter>flags</parameter> <type>text</type> ] )
3303 <returnvalue>boolean</returnvalue>
3304 </para>
3305 <para>
3306 Checks whether a match of the POSIX regular
3307 expression <parameter>pattern</parameter> occurs
3308 within <parameter>string</parameter>; see
3309 <xref linkend="functions-posix-regexp"/>.
3310 </para>
3311 <para>
3312 <literal>regexp_like('Hello World', 'world$', 'i')</literal>
3313 <returnvalue>t</returnvalue>
3314 </para></entry>
3315 </row>
3317 <row>
3318 <entry role="func_table_entry"><para role="func_signature">
3319 <indexterm>
3320 <primary>regexp_match</primary>
3321 </indexterm>
3322 <function>regexp_match</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3323 <returnvalue>text[]</returnvalue>
3324 </para>
3325 <para>
3326 Returns substrings within the first match of the POSIX regular
3327 expression <parameter>pattern</parameter> to
3328 the <parameter>string</parameter>; see
3329 <xref linkend="functions-posix-regexp"/>.
3330 </para>
3331 <para>
3332 <literal>regexp_match('foobarbequebaz', '(bar)(beque)')</literal>
3333 <returnvalue>{bar,beque}</returnvalue>
3334 </para></entry>
3335 </row>
3337 <row>
3338 <entry role="func_table_entry"><para role="func_signature">
3339 <indexterm>
3340 <primary>regexp_matches</primary>
3341 </indexterm>
3342 <function>regexp_matches</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3343 <returnvalue>setof text[]</returnvalue>
3344 </para>
3345 <para>
3346 Returns substrings within the first match of the POSIX regular
3347 expression <parameter>pattern</parameter> to
3348 the <parameter>string</parameter>, or substrings within all
3349 such matches if the <literal>g</literal> flag is used;
3350 see <xref linkend="functions-posix-regexp"/>.
3351 </para>
3352 <para>
3353 <literal>regexp_matches('foobarbequebaz', 'ba.', 'g')</literal>
3354 <returnvalue></returnvalue>
3355 <programlisting>
3356 {bar}
3357 {baz}
3358 </programlisting>
3359 </para></entry>
3360 </row>
3362 <row>
3363 <entry role="func_table_entry"><para role="func_signature">
3364 <indexterm>
3365 <primary>regexp_replace</primary>
3366 </indexterm>
3367 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>
3368 [, <parameter>start</parameter> <type>integer</type> ]
3369 [, <parameter>flags</parameter> <type>text</type> ] )
3370 <returnvalue>text</returnvalue>
3371 </para>
3372 <para>
3373 Replaces the substring that is the first match to the POSIX
3374 regular expression <parameter>pattern</parameter>, or all such
3375 matches if the <literal>g</literal> flag is used; see
3376 <xref linkend="functions-posix-regexp"/>.
3377 </para>
3378 <para>
3379 <literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal>
3380 <returnvalue>ThM</returnvalue>
3381 </para></entry>
3382 </row>
3384 <row>
3385 <entry role="func_table_entry"><para role="func_signature">
3386 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>,
3387 <parameter>start</parameter> <type>integer</type>,
3388 <parameter>N</parameter> <type>integer</type>
3389 [, <parameter>flags</parameter> <type>text</type> ] )
3390 <returnvalue>text</returnvalue>
3391 </para>
3392 <para>
3393 Replaces the substring that is the <parameter>N</parameter>'th
3394 match to the POSIX regular expression <parameter>pattern</parameter>,
3395 or all such matches if <parameter>N</parameter> is zero; see
3396 <xref linkend="functions-posix-regexp"/>.
3397 </para>
3398 <para>
3399 <literal>regexp_replace('Thomas', '.', 'X', 3, 2)</literal>
3400 <returnvalue>ThoXas</returnvalue>
3401 </para></entry>
3402 </row>
3404 <row>
3405 <entry role="func_table_entry"><para role="func_signature">
3406 <indexterm>
3407 <primary>regexp_split_to_array</primary>
3408 </indexterm>
3409 <function>regexp_split_to_array</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3410 <returnvalue>text[]</returnvalue>
3411 </para>
3412 <para>
3413 Splits <parameter>string</parameter> using a POSIX regular
3414 expression as the delimiter, producing an array of results; see
3415 <xref linkend="functions-posix-regexp"/>.
3416 </para>
3417 <para>
3418 <literal>regexp_split_to_array('hello world', '\s+')</literal>
3419 <returnvalue>{hello,world}</returnvalue>
3420 </para></entry>
3421 </row>
3423 <row>
3424 <entry role="func_table_entry"><para role="func_signature">
3425 <indexterm>
3426 <primary>regexp_split_to_table</primary>
3427 </indexterm>
3428 <function>regexp_split_to_table</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3429 <returnvalue>setof text</returnvalue>
3430 </para>
3431 <para>
3432 Splits <parameter>string</parameter> using a POSIX regular
3433 expression as the delimiter, producing a set of results; see
3434 <xref linkend="functions-posix-regexp"/>.
3435 </para>
3436 <para>
3437 <literal>regexp_split_to_table('hello world', '\s+')</literal>
3438 <returnvalue></returnvalue>
3439 <programlisting>
3440 hello
3441 world
3442 </programlisting>
3443 </para></entry>
3444 </row>
3446 <row>
3447 <entry role="func_table_entry"><para role="func_signature">
3448 <indexterm>
3449 <primary>regexp_substr</primary>
3450 </indexterm>
3451 <function>regexp_substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3452 [, <parameter>start</parameter> <type>integer</type>
3453 [, <parameter>N</parameter> <type>integer</type>
3454 [, <parameter>flags</parameter> <type>text</type>
3455 [, <parameter>subexpr</parameter> <type>integer</type> ] ] ] ] )
3456 <returnvalue>text</returnvalue>
3457 </para>
3458 <para>
3459 Returns the substring within <parameter>string</parameter> that
3460 matches the <parameter>N</parameter>'th occurrence of the POSIX
3461 regular expression <parameter>pattern</parameter>,
3462 or <literal>NULL</literal> if there is no such match; see
3463 <xref linkend="functions-posix-regexp"/>.
3464 </para>
3465 <para>
3466 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i')</literal>
3467 <returnvalue>CDEF</returnvalue>
3468 </para>
3469 <para>
3470 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i', 2)</literal>
3471 <returnvalue>EF</returnvalue>
3472 </para></entry>
3473 </row>
3475 <row>
3476 <entry role="func_table_entry"><para role="func_signature">
3477 <indexterm>
3478 <primary>repeat</primary>
3479 </indexterm>
3480 <function>repeat</function> ( <parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>integer</type> )
3481 <returnvalue>text</returnvalue>
3482 </para>
3483 <para>
3484 Repeats <parameter>string</parameter> the specified
3485 <parameter>number</parameter> of times.
3486 </para>
3487 <para>
3488 <literal>repeat('Pg', 4)</literal>
3489 <returnvalue>PgPgPgPg</returnvalue>
3490 </para></entry>
3491 </row>
3493 <row>
3494 <entry role="func_table_entry"><para role="func_signature">
3495 <indexterm>
3496 <primary>replace</primary>
3497 </indexterm>
3498 <function>replace</function> ( <parameter>string</parameter> <type>text</type>,
3499 <parameter>from</parameter> <type>text</type>,
3500 <parameter>to</parameter> <type>text</type> )
3501 <returnvalue>text</returnvalue>
3502 </para>
3503 <para>
3504 Replaces all occurrences in <parameter>string</parameter> of
3505 substring <parameter>from</parameter> with
3506 substring <parameter>to</parameter>.
3507 </para>
3508 <para>
3509 <literal>replace('abcdefabcdef', 'cd', 'XX')</literal>
3510 <returnvalue>abXXefabXXef</returnvalue>
3511 </para></entry>
3512 </row>
3514 <row>
3515 <entry role="func_table_entry"><para role="func_signature">
3516 <indexterm>
3517 <primary>reverse</primary>
3518 </indexterm>
3519 <function>reverse</function> ( <type>text</type> )
3520 <returnvalue>text</returnvalue>
3521 </para>
3522 <para>
3523 Reverses the order of the characters in the string.
3524 </para>
3525 <para>
3526 <literal>reverse('abcde')</literal>
3527 <returnvalue>edcba</returnvalue>
3528 </para></entry>
3529 </row>
3531 <row>
3532 <entry role="func_table_entry"><para role="func_signature">
3533 <indexterm>
3534 <primary>right</primary>
3535 </indexterm>
3536 <function>right</function> ( <parameter>string</parameter> <type>text</type>,
3537 <parameter>n</parameter> <type>integer</type> )
3538 <returnvalue>text</returnvalue>
3539 </para>
3540 <para>
3541 Returns last <parameter>n</parameter> characters in the string,
3542 or when <parameter>n</parameter> is negative, returns all but
3543 first |<parameter>n</parameter>| characters.
3544 </para>
3545 <para>
3546 <literal>right('abcde', 2)</literal>
3547 <returnvalue>de</returnvalue>
3548 </para></entry>
3549 </row>
3551 <row>
3552 <entry role="func_table_entry"><para role="func_signature">
3553 <indexterm>
3554 <primary>split_part</primary>
3555 </indexterm>
3556 <function>split_part</function> ( <parameter>string</parameter> <type>text</type>,
3557 <parameter>delimiter</parameter> <type>text</type>,
3558 <parameter>n</parameter> <type>integer</type> )
3559 <returnvalue>text</returnvalue>
3560 </para>
3561 <para>
3562 Splits <parameter>string</parameter> at occurrences
3563 of <parameter>delimiter</parameter> and returns
3564 the <parameter>n</parameter>'th field (counting from one),
3565 or when <parameter>n</parameter> is negative, returns
3566 the |<parameter>n</parameter>|'th-from-last field.
3567 </para>
3568 <para>
3569 <literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal>
3570 <returnvalue>def</returnvalue>
3571 </para>
3572 <para>
3573 <literal>split_part('abc,def,ghi,jkl', ',', -2)</literal>
3574 <returnvalue>ghi</returnvalue>
3575 </para></entry>
3576 </row>
3578 <row>
3579 <entry role="func_table_entry"><para role="func_signature">
3580 <indexterm>
3581 <primary>starts_with</primary>
3582 </indexterm>
3583 <function>starts_with</function> ( <parameter>string</parameter> <type>text</type>, <parameter>prefix</parameter> <type>text</type> )
3584 <returnvalue>boolean</returnvalue>
3585 </para>
3586 <para>
3587 Returns true if <parameter>string</parameter> starts
3588 with <parameter>prefix</parameter>.
3589 </para>
3590 <para>
3591 <literal>starts_with('alphabet', 'alph')</literal>
3592 <returnvalue>t</returnvalue>
3593 </para></entry>
3594 </row>
3596 <row>
3597 <entry role="func_table_entry"><para role="func_signature">
3598 <indexterm id="function-string-to-array">
3599 <primary>string_to_array</primary>
3600 </indexterm>
3601 <function>string_to_array</function> ( <parameter>string</parameter> <type>text</type>, <parameter>delimiter</parameter> <type>text</type> <optional>, <parameter>null_string</parameter> <type>text</type> </optional> )
3602 <returnvalue>text[]</returnvalue>
3603 </para>
3604 <para>
3605 Splits the <parameter>string</parameter> at occurrences
3606 of <parameter>delimiter</parameter> and forms the resulting fields
3607 into a <type>text</type> array.
3608 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3609 each character in the <parameter>string</parameter> will become a
3610 separate element in the array.
3611 If <parameter>delimiter</parameter> is an empty string, then
3612 the <parameter>string</parameter> is treated as a single field.
3613 If <parameter>null_string</parameter> is supplied and is
3614 not <literal>NULL</literal>, fields matching that string are
3615 replaced by <literal>NULL</literal>.
3616 See also <link linkend="function-array-to-string"><function>array_to_string</function></link>.
3617 </para>
3618 <para>
3619 <literal>string_to_array('xx~~yy~~zz', '~~', 'yy')</literal>
3620 <returnvalue>{xx,NULL,zz}</returnvalue>
3621 </para></entry>
3622 </row>
3624 <row>
3625 <entry role="func_table_entry"><para role="func_signature">
3626 <indexterm>
3627 <primary>string_to_table</primary>
3628 </indexterm>
3629 <function>string_to_table</function> ( <parameter>string</parameter> <type>text</type>, <parameter>delimiter</parameter> <type>text</type> <optional>, <parameter>null_string</parameter> <type>text</type> </optional> )
3630 <returnvalue>setof text</returnvalue>
3631 </para>
3632 <para>
3633 Splits the <parameter>string</parameter> at occurrences
3634 of <parameter>delimiter</parameter> and returns the resulting fields
3635 as a set of <type>text</type> rows.
3636 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3637 each character in the <parameter>string</parameter> will become a
3638 separate row of the result.
3639 If <parameter>delimiter</parameter> is an empty string, then
3640 the <parameter>string</parameter> is treated as a single field.
3641 If <parameter>null_string</parameter> is supplied and is
3642 not <literal>NULL</literal>, fields matching that string are
3643 replaced by <literal>NULL</literal>.
3644 </para>
3645 <para>
3646 <literal>string_to_table('xx~^~yy~^~zz', '~^~', 'yy')</literal>
3647 <returnvalue></returnvalue>
3648 <programlisting>
3650 NULL
3652 </programlisting>
3653 </para></entry>
3654 </row>
3656 <row>
3657 <entry role="func_table_entry"><para role="func_signature">
3658 <indexterm>
3659 <primary>strpos</primary>
3660 </indexterm>
3661 <function>strpos</function> ( <parameter>string</parameter> <type>text</type>, <parameter>substring</parameter> <type>text</type> )
3662 <returnvalue>integer</returnvalue>
3663 </para>
3664 <para>
3665 Returns first starting index of the specified <parameter>substring</parameter>
3666 within <parameter>string</parameter>, or zero if it's not present.
3667 (Same as <literal>position(<parameter>substring</parameter> in
3668 <parameter>string</parameter>)</literal>, but note the reversed
3669 argument order.)
3670 </para>
3671 <para>
3672 <literal>strpos('high', 'ig')</literal>
3673 <returnvalue>2</returnvalue>
3674 </para></entry>
3675 </row>
3677 <row>
3678 <entry role="func_table_entry"><para role="func_signature">
3679 <indexterm>
3680 <primary>substr</primary>
3681 </indexterm>
3682 <function>substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
3683 <returnvalue>text</returnvalue>
3684 </para>
3685 <para>
3686 Extracts the substring of <parameter>string</parameter> starting at
3687 the <parameter>start</parameter>'th character,
3688 and extending for <parameter>count</parameter> characters if that is
3689 specified. (Same
3690 as <literal>substring(<parameter>string</parameter>
3691 from <parameter>start</parameter>
3692 for <parameter>count</parameter>)</literal>.)
3693 </para>
3694 <para>
3695 <literal>substr('alphabet', 3)</literal>
3696 <returnvalue>phabet</returnvalue>
3697 </para>
3698 <para>
3699 <literal>substr('alphabet', 3, 2)</literal>
3700 <returnvalue>ph</returnvalue>
3701 </para></entry>
3702 </row>
3704 <row>
3705 <entry role="func_table_entry"><para role="func_signature">
3706 <indexterm>
3707 <primary>to_ascii</primary>
3708 </indexterm>
3709 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type> )
3710 <returnvalue>text</returnvalue>
3711 </para>
3712 <para role="func_signature">
3713 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3714 <parameter>encoding</parameter> <type>name</type> )
3715 <returnvalue>text</returnvalue>
3716 </para>
3717 <para role="func_signature">
3718 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3719 <parameter>encoding</parameter> <type>integer</type> )
3720 <returnvalue>text</returnvalue>
3721 </para>
3722 <para>
3723 Converts <parameter>string</parameter> to <acronym>ASCII</acronym>
3724 from another encoding, which may be identified by name or number.
3725 If <parameter>encoding</parameter> is omitted the database encoding
3726 is assumed (which in practice is the only useful case).
3727 The conversion consists primarily of dropping accents.
3728 Conversion is only supported
3729 from <literal>LATIN1</literal>, <literal>LATIN2</literal>,
3730 <literal>LATIN9</literal>, and <literal>WIN1250</literal> encodings.
3731 (See the <xref linkend="unaccent"/> module for another, more flexible
3732 solution.)
3733 </para>
3734 <para>
3735 <literal>to_ascii('Kar&eacute;l')</literal>
3736 <returnvalue>Karel</returnvalue>
3737 </para></entry>
3738 </row>
3740 <row>
3741 <entry role="func_table_entry"><para role="func_signature">
3742 <indexterm>
3743 <primary>to_hex</primary>
3744 </indexterm>
3745 <function>to_hex</function> ( <type>integer</type> )
3746 <returnvalue>text</returnvalue>
3747 </para>
3748 <para role="func_signature">
3749 <function>to_hex</function> ( <type>bigint</type> )
3750 <returnvalue>text</returnvalue>
3751 </para>
3752 <para>
3753 Converts the number to its equivalent hexadecimal representation.
3754 </para>
3755 <para>
3756 <literal>to_hex(2147483647)</literal>
3757 <returnvalue>7fffffff</returnvalue>
3758 </para></entry>
3759 </row>
3761 <row>
3762 <entry role="func_table_entry"><para role="func_signature">
3763 <indexterm>
3764 <primary>translate</primary>
3765 </indexterm>
3766 <function>translate</function> ( <parameter>string</parameter> <type>text</type>,
3767 <parameter>from</parameter> <type>text</type>,
3768 <parameter>to</parameter> <type>text</type> )
3769 <returnvalue>text</returnvalue>
3770 </para>
3771 <para>
3772 Replaces each character in <parameter>string</parameter> that
3773 matches a character in the <parameter>from</parameter> set with the
3774 corresponding character in the <parameter>to</parameter>
3775 set. If <parameter>from</parameter> is longer than
3776 <parameter>to</parameter>, occurrences of the extra characters in
3777 <parameter>from</parameter> are deleted.
3778 </para>
3779 <para>
3780 <literal>translate('12345', '143', 'ax')</literal>
3781 <returnvalue>a2x5</returnvalue>
3782 </para></entry>
3783 </row>
3785 <row>
3786 <entry role="func_table_entry"><para role="func_signature">
3787 <indexterm>
3788 <primary>unistr</primary>
3789 </indexterm>
3790 <function>unistr</function> ( <type>text</type> )
3791 <returnvalue>text</returnvalue>
3792 </para>
3793 <para>
3794 Evaluate escaped Unicode characters in the argument. Unicode characters
3795 can be specified as
3796 <literal>\<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3797 digits), <literal>\+<replaceable>XXXXXX</replaceable></literal> (6
3798 hexadecimal digits),
3799 <literal>\u<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3800 digits), or <literal>\U<replaceable>XXXXXXXX</replaceable></literal>
3801 (8 hexadecimal digits). To specify a backslash, write two
3802 backslashes. All other characters are taken literally.
3803 </para>
3805 <para>
3806 If the server encoding is not UTF-8, the Unicode code point identified
3807 by one of these escape sequences is converted to the actual server
3808 encoding; an error is reported if that's not possible.
3809 </para>
3811 <para>
3812 This function provides a (non-standard) alternative to string
3813 constants with Unicode escapes (see <xref
3814 linkend="sql-syntax-strings-uescape"/>).
3815 </para>
3817 <para>
3818 <literal>unistr('d\0061t\+000061')</literal>
3819 <returnvalue>data</returnvalue>
3820 </para>
3821 <para>
3822 <literal>unistr('d\u0061t\U00000061')</literal>
3823 <returnvalue>data</returnvalue>
3824 </para></entry>
3825 </row>
3827 </tbody>
3828 </tgroup>
3829 </table>
3831 <para>
3832 The <function>concat</function>, <function>concat_ws</function> and
3833 <function>format</function> functions are variadic, so it is possible to
3834 pass the values to be concatenated or formatted as an array marked with
3835 the <literal>VARIADIC</literal> keyword (see <xref
3836 linkend="xfunc-sql-variadic-functions"/>). The array's elements are
3837 treated as if they were separate ordinary arguments to the function.
3838 If the variadic array argument is NULL, <function>concat</function>
3839 and <function>concat_ws</function> return NULL, but
3840 <function>format</function> treats a NULL as a zero-element array.
3841 </para>
3843 <para>
3844 See also the aggregate function <function>string_agg</function> in
3845 <xref linkend="functions-aggregate"/>, and the functions for
3846 converting between strings and the <type>bytea</type> type in
3847 <xref linkend="functions-binarystring-conversions"/>.
3848 </para>
3850 <sect2 id="functions-string-format">
3851 <title><function>format</function></title>
3853 <indexterm>
3854 <primary>format</primary>
3855 </indexterm>
3857 <para>
3858 The function <function>format</function> produces output formatted according to
3859 a format string, in a style similar to the C function
3860 <function>sprintf</function>.
3861 </para>
3863 <para>
3864 <synopsis>
3865 <function>format</function>(<parameter>formatstr</parameter> <type>text</type> [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])
3866 </synopsis>
3867 <parameter>formatstr</parameter> is a format string that specifies how the
3868 result should be formatted. Text in the format string is copied
3869 directly to the result, except where <firstterm>format specifiers</firstterm> are
3870 used. Format specifiers act as placeholders in the string, defining how
3871 subsequent function arguments should be formatted and inserted into the
3872 result. Each <parameter>formatarg</parameter> argument is converted to text
3873 according to the usual output rules for its data type, and then formatted
3874 and inserted into the result string according to the format specifier(s).
3875 </para>
3877 <para>
3878 Format specifiers are introduced by a <literal>%</literal> character and have
3879 the form
3880 <synopsis>
3881 %[<parameter>position</parameter>][<parameter>flags</parameter>][<parameter>width</parameter>]<parameter>type</parameter>
3882 </synopsis>
3883 where the component fields are:
3885 <variablelist>
3886 <varlistentry>
3887 <term><parameter>position</parameter> (optional)</term>
3888 <listitem>
3889 <para>
3890 A string of the form <literal><parameter>n</parameter>$</literal> where
3891 <parameter>n</parameter> is the index of the argument to print.
3892 Index 1 means the first argument after
3893 <parameter>formatstr</parameter>. If the <parameter>position</parameter> is
3894 omitted, the default is to use the next argument in sequence.
3895 </para>
3896 </listitem>
3897 </varlistentry>
3899 <varlistentry>
3900 <term><parameter>flags</parameter> (optional)</term>
3901 <listitem>
3902 <para>
3903 Additional options controlling how the format specifier's output is
3904 formatted. Currently the only supported flag is a minus sign
3905 (<literal>-</literal>) which will cause the format specifier's output to be
3906 left-justified. This has no effect unless the <parameter>width</parameter>
3907 field is also specified.
3908 </para>
3909 </listitem>
3910 </varlistentry>
3912 <varlistentry>
3913 <term><parameter>width</parameter> (optional)</term>
3914 <listitem>
3915 <para>
3916 Specifies the <emphasis>minimum</emphasis> number of characters to use to
3917 display the format specifier's output. The output is padded on the
3918 left or right (depending on the <literal>-</literal> flag) with spaces as
3919 needed to fill the width. A too-small width does not cause
3920 truncation of the output, but is simply ignored. The width may be
3921 specified using any of the following: a positive integer; an
3922 asterisk (<literal>*</literal>) to use the next function argument as the
3923 width; or a string of the form <literal>*<parameter>n</parameter>$</literal> to
3924 use the <parameter>n</parameter>th function argument as the width.
3925 </para>
3927 <para>
3928 If the width comes from a function argument, that argument is
3929 consumed before the argument that is used for the format specifier's
3930 value. If the width argument is negative, the result is left
3931 aligned (as if the <literal>-</literal> flag had been specified) within a
3932 field of length <function>abs</function>(<parameter>width</parameter>).
3933 </para>
3934 </listitem>
3935 </varlistentry>
3937 <varlistentry>
3938 <term><parameter>type</parameter> (required)</term>
3939 <listitem>
3940 <para>
3941 The type of format conversion to use to produce the format
3942 specifier's output. The following types are supported:
3943 <itemizedlist>
3944 <listitem>
3945 <para>
3946 <literal>s</literal> formats the argument value as a simple
3947 string. A null value is treated as an empty string.
3948 </para>
3949 </listitem>
3950 <listitem>
3951 <para>
3952 <literal>I</literal> treats the argument value as an SQL
3953 identifier, double-quoting it if necessary.
3954 It is an error for the value to be null (equivalent to
3955 <function>quote_ident</function>).
3956 </para>
3957 </listitem>
3958 <listitem>
3959 <para>
3960 <literal>L</literal> quotes the argument value as an SQL literal.
3961 A null value is displayed as the string <literal>NULL</literal>, without
3962 quotes (equivalent to <function>quote_nullable</function>).
3963 </para>
3964 </listitem>
3965 </itemizedlist>
3966 </para>
3967 </listitem>
3968 </varlistentry>
3969 </variablelist>
3970 </para>
3972 <para>
3973 In addition to the format specifiers described above, the special sequence
3974 <literal>%%</literal> may be used to output a literal <literal>%</literal> character.
3975 </para>
3977 <para>
3978 Here are some examples of the basic format conversions:
3980 <screen>
3981 SELECT format('Hello %s', 'World');
3982 <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
3984 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
3985 <lineannotation>Result: </lineannotation><computeroutput>Testing one, two, three, %</computeroutput>
3987 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
3988 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
3990 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
3991 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')</computeroutput>
3992 </screen>
3993 </para>
3995 <para>
3996 Here are examples using <parameter>width</parameter> fields
3997 and the <literal>-</literal> flag:
3999 <screen>
4000 SELECT format('|%10s|', 'foo');
4001 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4003 SELECT format('|%-10s|', 'foo');
4004 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4006 SELECT format('|%*s|', 10, 'foo');
4007 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4009 SELECT format('|%*s|', -10, 'foo');
4010 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4012 SELECT format('|%-*s|', 10, 'foo');
4013 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4015 SELECT format('|%-*s|', -10, 'foo');
4016 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4017 </screen>
4018 </para>
4020 <para>
4021 These examples show use of <parameter>position</parameter> fields:
4023 <screen>
4024 SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
4025 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, one</computeroutput>
4027 SELECT format('|%*2$s|', 'foo', 10, 'bar');
4028 <lineannotation>Result: </lineannotation><computeroutput>| bar|</computeroutput>
4030 SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
4031 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4032 </screen>
4033 </para>
4035 <para>
4036 Unlike the standard C function <function>sprintf</function>,
4037 <productname>PostgreSQL</productname>'s <function>format</function> function allows format
4038 specifiers with and without <parameter>position</parameter> fields to be mixed
4039 in the same format string. A format specifier without a
4040 <parameter>position</parameter> field always uses the next argument after the
4041 last argument consumed.
4042 In addition, the <function>format</function> function does not require all
4043 function arguments to be used in the format string.
4044 For example:
4046 <screen>
4047 SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
4048 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, three</computeroutput>
4049 </screen>
4050 </para>
4052 <para>
4053 The <literal>%I</literal> and <literal>%L</literal> format specifiers are particularly
4054 useful for safely constructing dynamic SQL statements. See
4055 <xref linkend="plpgsql-quote-literal-example"/>.
4056 </para>
4057 </sect2>
4059 </sect1>
4062 <sect1 id="functions-binarystring">
4063 <title>Binary String Functions and Operators</title>
4065 <indexterm zone="functions-binarystring">
4066 <primary>binary data</primary>
4067 <secondary>functions</secondary>
4068 </indexterm>
4070 <para>
4071 This section describes functions and operators for examining and
4072 manipulating binary strings, that is values of type <type>bytea</type>.
4073 Many of these are equivalent, in purpose and syntax, to the
4074 text-string functions described in the previous section.
4075 </para>
4077 <para>
4078 <acronym>SQL</acronym> defines some string functions that use
4079 key words, rather than commas, to separate
4080 arguments. Details are in
4081 <xref linkend="functions-binarystring-sql"/>.
4082 <productname>PostgreSQL</productname> also provides versions of these functions
4083 that use the regular function invocation syntax
4084 (see <xref linkend="functions-binarystring-other"/>).
4085 </para>
4087 <table id="functions-binarystring-sql">
4088 <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
4089 <tgroup cols="1">
4090 <thead>
4091 <row>
4092 <entry role="func_table_entry"><para role="func_signature">
4093 Function/Operator
4094 </para>
4095 <para>
4096 Description
4097 </para>
4098 <para>
4099 Example(s)
4100 </para></entry>
4101 </row>
4102 </thead>
4104 <tbody>
4105 <row>
4106 <entry role="func_table_entry"><para role="func_signature">
4107 <indexterm>
4108 <primary>binary string</primary>
4109 <secondary>concatenation</secondary>
4110 </indexterm>
4111 <type>bytea</type> <literal>||</literal> <type>bytea</type>
4112 <returnvalue>bytea</returnvalue>
4113 </para>
4114 <para>
4115 Concatenates the two binary strings.
4116 </para>
4117 <para>
4118 <literal>'\x123456'::bytea || '\x789a00bcde'::bytea</literal>
4119 <returnvalue>\x123456789a00bcde</returnvalue>
4120 </para></entry>
4121 </row>
4123 <row>
4124 <entry role="func_table_entry"><para role="func_signature">
4125 <indexterm>
4126 <primary>bit_length</primary>
4127 </indexterm>
4128 <function>bit_length</function> ( <type>bytea</type> )
4129 <returnvalue>integer</returnvalue>
4130 </para>
4131 <para>
4132 Returns number of bits in the binary string (8
4133 times the <function>octet_length</function>).
4134 </para>
4135 <para>
4136 <literal>bit_length('\x123456'::bytea)</literal>
4137 <returnvalue>24</returnvalue>
4138 </para></entry>
4139 </row>
4141 <row>
4142 <entry role="func_table_entry"><para role="func_signature">
4143 <indexterm>
4144 <primary>btrim</primary>
4145 </indexterm>
4146 <function>btrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4147 <parameter>bytesremoved</parameter> <type>bytea</type> )
4148 <returnvalue>bytea</returnvalue>
4149 </para>
4150 <para>
4151 Removes the longest string containing only bytes appearing in
4152 <parameter>bytesremoved</parameter> from the start and end of
4153 <parameter>bytes</parameter>.
4154 </para>
4155 <para>
4156 <literal>btrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4157 <returnvalue>\x345678</returnvalue>
4158 </para></entry>
4159 </row>
4161 <row>
4162 <entry role="func_table_entry"><para role="func_signature">
4163 <indexterm>
4164 <primary>ltrim</primary>
4165 </indexterm>
4166 <function>ltrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4167 <parameter>bytesremoved</parameter> <type>bytea</type> )
4168 <returnvalue>bytea</returnvalue>
4169 </para>
4170 <para>
4171 Removes the longest string containing only bytes appearing in
4172 <parameter>bytesremoved</parameter> from the start of
4173 <parameter>bytes</parameter>.
4174 </para>
4175 <para>
4176 <literal>ltrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4177 <returnvalue>\x34567890</returnvalue>
4178 </para></entry>
4179 </row>
4181 <row>
4182 <entry role="func_table_entry"><para role="func_signature">
4183 <indexterm>
4184 <primary>octet_length</primary>
4185 </indexterm>
4186 <function>octet_length</function> ( <type>bytea</type> )
4187 <returnvalue>integer</returnvalue>
4188 </para>
4189 <para>
4190 Returns number of bytes in the binary string.
4191 </para>
4192 <para>
4193 <literal>octet_length('\x123456'::bytea)</literal>
4194 <returnvalue>3</returnvalue>
4195 </para></entry>
4196 </row>
4198 <row>
4199 <entry role="func_table_entry"><para role="func_signature">
4200 <indexterm>
4201 <primary>overlay</primary>
4202 </indexterm>
4203 <function>overlay</function> ( <parameter>bytes</parameter> <type>bytea</type> <literal>PLACING</literal> <parameter>newsubstring</parameter> <type>bytea</type> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> )
4204 <returnvalue>bytea</returnvalue>
4205 </para>
4206 <para>
4207 Replaces the substring of <parameter>bytes</parameter> that starts at
4208 the <parameter>start</parameter>'th byte and extends
4209 for <parameter>count</parameter> bytes
4210 with <parameter>newsubstring</parameter>.
4211 If <parameter>count</parameter> is omitted, it defaults to the length
4212 of <parameter>newsubstring</parameter>.
4213 </para>
4214 <para>
4215 <literal>overlay('\x1234567890'::bytea placing '\002\003'::bytea from 2 for 3)</literal>
4216 <returnvalue>\x12020390</returnvalue>
4217 </para></entry>
4218 </row>
4220 <row>
4221 <entry role="func_table_entry"><para role="func_signature">
4222 <indexterm>
4223 <primary>position</primary>
4224 </indexterm>
4225 <function>position</function> ( <parameter>substring</parameter> <type>bytea</type> <literal>IN</literal> <parameter>bytes</parameter> <type>bytea</type> )
4226 <returnvalue>integer</returnvalue>
4227 </para>
4228 <para>
4229 Returns first starting index of the specified
4230 <parameter>substring</parameter> within
4231 <parameter>bytes</parameter>, or zero if it's not present.
4232 </para>
4233 <para>
4234 <literal>position('\x5678'::bytea in '\x1234567890'::bytea)</literal>
4235 <returnvalue>3</returnvalue>
4236 </para></entry>
4237 </row>
4239 <row>
4240 <entry role="func_table_entry"><para role="func_signature">
4241 <indexterm>
4242 <primary>rtrim</primary>
4243 </indexterm>
4244 <function>rtrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4245 <parameter>bytesremoved</parameter> <type>bytea</type> )
4246 <returnvalue>bytea</returnvalue>
4247 </para>
4248 <para>
4249 Removes the longest string containing only bytes appearing in
4250 <parameter>bytesremoved</parameter> from the end of
4251 <parameter>bytes</parameter>.
4252 </para>
4253 <para>
4254 <literal>rtrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4255 <returnvalue>\x12345678</returnvalue>
4256 </para></entry>
4257 </row>
4259 <row>
4260 <entry role="func_table_entry"><para role="func_signature">
4261 <indexterm>
4262 <primary>substring</primary>
4263 </indexterm>
4264 <function>substring</function> ( <parameter>bytes</parameter> <type>bytea</type> <optional> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> </optional> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> )
4265 <returnvalue>bytea</returnvalue>
4266 </para>
4267 <para>
4268 Extracts the substring of <parameter>bytes</parameter> starting at
4269 the <parameter>start</parameter>'th byte if that is specified,
4270 and stopping after <parameter>count</parameter> bytes if that is
4271 specified. Provide at least one of <parameter>start</parameter>
4272 and <parameter>count</parameter>.
4273 </para>
4274 <para>
4275 <literal>substring('\x1234567890'::bytea from 3 for 2)</literal>
4276 <returnvalue>\x5678</returnvalue>
4277 </para></entry>
4278 </row>
4280 <row>
4281 <entry role="func_table_entry"><para role="func_signature">
4282 <indexterm>
4283 <primary>trim</primary>
4284 </indexterm>
4285 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
4286 <parameter>bytesremoved</parameter> <type>bytea</type> <literal>FROM</literal>
4287 <parameter>bytes</parameter> <type>bytea</type> )
4288 <returnvalue>bytea</returnvalue>
4289 </para>
4290 <para>
4291 Removes the longest string containing only bytes appearing in
4292 <parameter>bytesremoved</parameter> from the start,
4293 end, or both ends (<literal>BOTH</literal> is the default)
4294 of <parameter>bytes</parameter>.
4295 </para>
4296 <para>
4297 <literal>trim('\x9012'::bytea from '\x1234567890'::bytea)</literal>
4298 <returnvalue>\x345678</returnvalue>
4299 </para></entry>
4300 </row>
4302 <row>
4303 <entry role="func_table_entry"><para role="func_signature">
4304 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
4305 <parameter>bytes</parameter> <type>bytea</type>,
4306 <parameter>bytesremoved</parameter> <type>bytea</type> )
4307 <returnvalue>bytea</returnvalue>
4308 </para>
4309 <para>
4310 This is a non-standard syntax for <function>trim()</function>.
4311 </para>
4312 <para>
4313 <literal>trim(both from '\x1234567890'::bytea, '\x9012'::bytea)</literal>
4314 <returnvalue>\x345678</returnvalue>
4315 </para></entry>
4316 </row>
4317 </tbody>
4318 </tgroup>
4319 </table>
4321 <para>
4322 Additional binary string manipulation functions are available and
4323 are listed in <xref linkend="functions-binarystring-other"/>. Some
4324 of them are used internally to implement the
4325 <acronym>SQL</acronym>-standard string functions listed in <xref
4326 linkend="functions-binarystring-sql"/>.
4327 </para>
4329 <table id="functions-binarystring-other">
4330 <title>Other Binary String Functions</title>
4331 <tgroup cols="1">
4332 <thead>
4333 <row>
4334 <entry role="func_table_entry"><para role="func_signature">
4335 Function
4336 </para>
4337 <para>
4338 Description
4339 </para>
4340 <para>
4341 Example(s)
4342 </para></entry>
4343 </row>
4344 </thead>
4346 <tbody>
4347 <row>
4348 <entry role="func_table_entry"><para role="func_signature">
4349 <indexterm>
4350 <primary>bit_count</primary>
4351 </indexterm>
4352 <indexterm>
4353 <primary>popcount</primary>
4354 <see>bit_count</see>
4355 </indexterm>
4356 <function>bit_count</function> ( <parameter>bytes</parameter> <type>bytea</type> )
4357 <returnvalue>bigint</returnvalue>
4358 </para>
4359 <para>
4360 Returns the number of bits set in the binary string (also known as
4361 <quote>popcount</quote>).
4362 </para>
4363 <para>
4364 <literal>bit_count('\x1234567890'::bytea)</literal>
4365 <returnvalue>15</returnvalue>
4366 </para></entry>
4367 </row>
4369 <row>
4370 <entry role="func_table_entry"><para role="func_signature">
4371 <indexterm>
4372 <primary>get_bit</primary>
4373 </indexterm>
4374 <function>get_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4375 <parameter>n</parameter> <type>bigint</type> )
4376 <returnvalue>integer</returnvalue>
4377 </para>
4378 <para>
4379 Extracts <link linkend="functions-zerobased-note">n'th</link> bit
4380 from binary string.
4381 </para>
4382 <para>
4383 <literal>get_bit('\x1234567890'::bytea, 30)</literal>
4384 <returnvalue>1</returnvalue>
4385 </para></entry>
4386 </row>
4388 <row>
4389 <entry role="func_table_entry"><para role="func_signature">
4390 <indexterm>
4391 <primary>get_byte</primary>
4392 </indexterm>
4393 <function>get_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4394 <parameter>n</parameter> <type>integer</type> )
4395 <returnvalue>integer</returnvalue>
4396 </para>
4397 <para>
4398 Extracts <link linkend="functions-zerobased-note">n'th</link> byte
4399 from binary string.
4400 </para>
4401 <para>
4402 <literal>get_byte('\x1234567890'::bytea, 4)</literal>
4403 <returnvalue>144</returnvalue>
4404 </para></entry>
4405 </row>
4407 <row>
4408 <entry role="func_table_entry"><para role="func_signature">
4409 <indexterm>
4410 <primary>length</primary>
4411 </indexterm>
4412 <indexterm>
4413 <primary>binary string</primary>
4414 <secondary>length</secondary>
4415 </indexterm>
4416 <indexterm>
4417 <primary>length</primary>
4418 <secondary sortas="binary string">of a binary string</secondary>
4419 <see>binary strings, length</see>
4420 </indexterm>
4421 <function>length</function> ( <type>bytea</type> )
4422 <returnvalue>integer</returnvalue>
4423 </para>
4424 <para>
4425 Returns the number of bytes in the binary string.
4426 </para>
4427 <para>
4428 <literal>length('\x1234567890'::bytea)</literal>
4429 <returnvalue>5</returnvalue>
4430 </para></entry>
4431 </row>
4433 <row>
4434 <entry role="func_table_entry"><para role="func_signature">
4435 <function>length</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4436 <parameter>encoding</parameter> <type>name</type> )
4437 <returnvalue>integer</returnvalue>
4438 </para>
4439 <para>
4440 Returns the number of characters in the binary string, assuming
4441 that it is text in the given <parameter>encoding</parameter>.
4442 </para>
4443 <para>
4444 <literal>length('jose'::bytea, 'UTF8')</literal>
4445 <returnvalue>4</returnvalue>
4446 </para></entry>
4447 </row>
4449 <row>
4450 <entry role="func_table_entry"><para role="func_signature">
4451 <indexterm>
4452 <primary>md5</primary>
4453 </indexterm>
4454 <function>md5</function> ( <type>bytea</type> )
4455 <returnvalue>text</returnvalue>
4456 </para>
4457 <para>
4458 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
4459 the binary string, with the result written in hexadecimal.
4460 </para>
4461 <para>
4462 <literal>md5('Th\000omas'::bytea)</literal>
4463 <returnvalue>8ab2d3c9689aaf18&zwsp;b4958c334c82d8b1</returnvalue>
4464 </para></entry>
4465 </row>
4467 <row>
4468 <entry role="func_table_entry"><para role="func_signature">
4469 <indexterm>
4470 <primary>set_bit</primary>
4471 </indexterm>
4472 <function>set_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4473 <parameter>n</parameter> <type>bigint</type>,
4474 <parameter>newvalue</parameter> <type>integer</type> )
4475 <returnvalue>bytea</returnvalue>
4476 </para>
4477 <para>
4478 Sets <link linkend="functions-zerobased-note">n'th</link> bit in
4479 binary string to <parameter>newvalue</parameter>.
4480 </para>
4481 <para>
4482 <literal>set_bit('\x1234567890'::bytea, 30, 0)</literal>
4483 <returnvalue>\x1234563890</returnvalue>
4484 </para></entry>
4485 </row>
4487 <row>
4488 <entry role="func_table_entry"><para role="func_signature">
4489 <indexterm>
4490 <primary>set_byte</primary>
4491 </indexterm>
4492 <function>set_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4493 <parameter>n</parameter> <type>integer</type>,
4494 <parameter>newvalue</parameter> <type>integer</type> )
4495 <returnvalue>bytea</returnvalue>
4496 </para>
4497 <para>
4498 Sets <link linkend="functions-zerobased-note">n'th</link> byte in
4499 binary string to <parameter>newvalue</parameter>.
4500 </para>
4501 <para>
4502 <literal>set_byte('\x1234567890'::bytea, 4, 64)</literal>
4503 <returnvalue>\x1234567840</returnvalue>
4504 </para></entry>
4505 </row>
4507 <row>
4508 <entry role="func_table_entry"><para role="func_signature">
4509 <indexterm>
4510 <primary>sha224</primary>
4511 </indexterm>
4512 <function>sha224</function> ( <type>bytea</type> )
4513 <returnvalue>bytea</returnvalue>
4514 </para>
4515 <para>
4516 Computes the SHA-224 <link linkend="functions-hash-note">hash</link>
4517 of the binary string.
4518 </para>
4519 <para>
4520 <literal>sha224('abc'::bytea)</literal>
4521 <returnvalue>\x23097d223405d8228642a477bda2&zwsp;55b32aadbce4bda0b3f7e36c9da7</returnvalue>
4522 </para></entry>
4523 </row>
4525 <row>
4526 <entry role="func_table_entry"><para role="func_signature">
4527 <indexterm>
4528 <primary>sha256</primary>
4529 </indexterm>
4530 <function>sha256</function> ( <type>bytea</type> )
4531 <returnvalue>bytea</returnvalue>
4532 </para>
4533 <para>
4534 Computes the SHA-256 <link linkend="functions-hash-note">hash</link>
4535 of the binary string.
4536 </para>
4537 <para>
4538 <literal>sha256('abc'::bytea)</literal>
4539 <returnvalue>\xba7816bf8f01cfea414140de5dae2223&zwsp;b00361a396177a9cb410ff61f20015ad</returnvalue>
4540 </para></entry>
4541 </row>
4543 <row>
4544 <entry role="func_table_entry"><para role="func_signature">
4545 <indexterm>
4546 <primary>sha384</primary>
4547 </indexterm>
4548 <function>sha384</function> ( <type>bytea</type> )
4549 <returnvalue>bytea</returnvalue>
4550 </para>
4551 <para>
4552 Computes the SHA-384 <link linkend="functions-hash-note">hash</link>
4553 of the binary string.
4554 </para>
4555 <para>
4556 <literal>sha384('abc'::bytea)</literal>
4557 <returnvalue>\xcb00753f45a35e8bb5a03d699ac65007&zwsp;272c32ab0eded1631a8b605a43ff5bed&zwsp;8086072ba1e7cc2358baeca134c825a7</returnvalue>
4558 </para></entry>
4559 </row>
4561 <row>
4562 <entry role="func_table_entry"><para role="func_signature">
4563 <indexterm>
4564 <primary>sha512</primary>
4565 </indexterm>
4566 <function>sha512</function> ( <type>bytea</type> )
4567 <returnvalue>bytea</returnvalue>
4568 </para>
4569 <para>
4570 Computes the SHA-512 <link linkend="functions-hash-note">hash</link>
4571 of the binary string.
4572 </para>
4573 <para>
4574 <literal>sha512('abc'::bytea)</literal>
4575 <returnvalue>\xddaf35a193617abacc417349ae204131&zwsp;12e6fa4e89a97ea20a9eeee64b55d39a&zwsp;2192992a274fc1a836ba3c23a3feebbd&zwsp;454d4423643ce80e2a9ac94fa54ca49f</returnvalue>
4576 </para></entry>
4577 </row>
4579 <row>
4580 <entry role="func_table_entry"><para role="func_signature">
4581 <indexterm>
4582 <primary>substr</primary>
4583 </indexterm>
4584 <function>substr</function> ( <parameter>bytes</parameter> <type>bytea</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
4585 <returnvalue>bytea</returnvalue>
4586 </para>
4587 <para>
4588 Extracts the substring of <parameter>bytes</parameter> starting at
4589 the <parameter>start</parameter>'th byte,
4590 and extending for <parameter>count</parameter> bytes if that is
4591 specified. (Same
4592 as <literal>substring(<parameter>bytes</parameter>
4593 from <parameter>start</parameter>
4594 for <parameter>count</parameter>)</literal>.)
4595 </para>
4596 <para>
4597 <literal>substr('\x1234567890'::bytea, 3, 2)</literal>
4598 <returnvalue>\x5678</returnvalue>
4599 </para></entry>
4600 </row>
4601 </tbody>
4602 </tgroup>
4603 </table>
4605 <para id="functions-zerobased-note">
4606 Functions <function>get_byte</function> and <function>set_byte</function>
4607 number the first byte of a binary string as byte 0.
4608 Functions <function>get_bit</function> and <function>set_bit</function>
4609 number bits from the right within each byte; for example bit 0 is the least
4610 significant bit of the first byte, and bit 15 is the most significant bit
4611 of the second byte.
4612 </para>
4614 <para id="functions-hash-note">
4615 For historical reasons, the function <function>md5</function>
4616 returns a hex-encoded value of type <type>text</type> whereas the SHA-2
4617 functions return type <type>bytea</type>. Use the functions
4618 <link linkend="function-encode"><function>encode</function></link>
4619 and <link linkend="function-decode"><function>decode</function></link> to
4620 convert between the two. For example write <literal>encode(sha256('abc'),
4621 'hex')</literal> to get a hex-encoded text representation,
4622 or <literal>decode(md5('abc'), 'hex')</literal> to get
4623 a <type>bytea</type> value.
4624 </para>
4626 <para>
4627 <indexterm>
4628 <primary>character string</primary>
4629 <secondary>converting to binary string</secondary>
4630 </indexterm>
4631 <indexterm>
4632 <primary>binary string</primary>
4633 <secondary>converting to character string</secondary>
4634 </indexterm>
4635 Functions for converting strings between different character sets
4636 (encodings), and for representing arbitrary binary data in textual
4637 form, are shown in
4638 <xref linkend="functions-binarystring-conversions"/>. For these
4639 functions, an argument or result of type <type>text</type> is expressed
4640 in the database's default encoding, while arguments or results of
4641 type <type>bytea</type> are in an encoding named by another argument.
4642 </para>
4644 <table id="functions-binarystring-conversions">
4645 <title>Text/Binary String Conversion Functions</title>
4646 <tgroup cols="1">
4647 <thead>
4648 <row>
4649 <entry role="func_table_entry"><para role="func_signature">
4650 Function
4651 </para>
4652 <para>
4653 Description
4654 </para>
4655 <para>
4656 Example(s)
4657 </para></entry>
4658 </row>
4659 </thead>
4661 <tbody>
4662 <row>
4663 <entry role="func_table_entry"><para role="func_signature">
4664 <indexterm>
4665 <primary>convert</primary>
4666 </indexterm>
4667 <function>convert</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4668 <parameter>src_encoding</parameter> <type>name</type>,
4669 <parameter>dest_encoding</parameter> <type>name</type> )
4670 <returnvalue>bytea</returnvalue>
4671 </para>
4672 <para>
4673 Converts a binary string representing text in
4674 encoding <parameter>src_encoding</parameter>
4675 to a binary string in encoding <parameter>dest_encoding</parameter>
4676 (see <xref linkend="multibyte-conversions-supported"/> for
4677 available conversions).
4678 </para>
4679 <para>
4680 <literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal>
4681 <returnvalue>\x746578745f696e5f75746638</returnvalue>
4682 </para></entry>
4683 </row>
4685 <row>
4686 <entry role="func_table_entry"><para role="func_signature">
4687 <indexterm>
4688 <primary>convert_from</primary>
4689 </indexterm>
4690 <function>convert_from</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4691 <parameter>src_encoding</parameter> <type>name</type> )
4692 <returnvalue>text</returnvalue>
4693 </para>
4694 <para>
4695 Converts a binary string representing text in
4696 encoding <parameter>src_encoding</parameter>
4697 to <type>text</type> in the database encoding
4698 (see <xref linkend="multibyte-conversions-supported"/> for
4699 available conversions).
4700 </para>
4701 <para>
4702 <literal>convert_from('text_in_utf8', 'UTF8')</literal>
4703 <returnvalue>text_in_utf8</returnvalue>
4704 </para></entry>
4705 </row>
4707 <row>
4708 <entry role="func_table_entry"><para role="func_signature">
4709 <indexterm>
4710 <primary>convert_to</primary>
4711 </indexterm>
4712 <function>convert_to</function> ( <parameter>string</parameter> <type>text</type>,
4713 <parameter>dest_encoding</parameter> <type>name</type> )
4714 <returnvalue>bytea</returnvalue>
4715 </para>
4716 <para>
4717 Converts a <type>text</type> string (in the database encoding) to a
4718 binary string encoded in encoding <parameter>dest_encoding</parameter>
4719 (see <xref linkend="multibyte-conversions-supported"/> for
4720 available conversions).
4721 </para>
4722 <para>
4723 <literal>convert_to('some_text', 'UTF8')</literal>
4724 <returnvalue>\x736f6d655f74657874</returnvalue>
4725 </para></entry>
4726 </row>
4728 <row>
4729 <entry role="func_table_entry"><para role="func_signature">
4730 <indexterm id="function-encode">
4731 <primary>encode</primary>
4732 </indexterm>
4733 <function>encode</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4734 <parameter>format</parameter> <type>text</type> )
4735 <returnvalue>text</returnvalue>
4736 </para>
4737 <para>
4738 Encodes binary data into a textual representation; supported
4739 <parameter>format</parameter> values are:
4740 <link linkend="encode-format-base64"><literal>base64</literal></link>,
4741 <link linkend="encode-format-escape"><literal>escape</literal></link>,
4742 <link linkend="encode-format-hex"><literal>hex</literal></link>.
4743 </para>
4744 <para>
4745 <literal>encode('123\000\001', 'base64')</literal>
4746 <returnvalue>MTIzAAE=</returnvalue>
4747 </para></entry>
4748 </row>
4750 <row>
4751 <entry role="func_table_entry"><para role="func_signature">
4752 <indexterm id="function-decode">
4753 <primary>decode</primary>
4754 </indexterm>
4755 <function>decode</function> ( <parameter>string</parameter> <type>text</type>,
4756 <parameter>format</parameter> <type>text</type> )
4757 <returnvalue>bytea</returnvalue>
4758 </para>
4759 <para>
4760 Decodes binary data from a textual representation; supported
4761 <parameter>format</parameter> values are the same as
4762 for <function>encode</function>.
4763 </para>
4764 <para>
4765 <literal>decode('MTIzAAE=', 'base64')</literal>
4766 <returnvalue>\x3132330001</returnvalue>
4767 </para></entry>
4768 </row>
4769 </tbody>
4770 </tgroup>
4771 </table>
4773 <para>
4774 The <function>encode</function> and <function>decode</function>
4775 functions support the following textual formats:
4777 <variablelist>
4778 <varlistentry id="encode-format-base64">
4779 <term>base64
4780 <indexterm>
4781 <primary>base64 format</primary>
4782 </indexterm></term>
4783 <listitem>
4784 <para>
4785 The <literal>base64</literal> format is that
4786 of <ulink url="https://datatracker.ietf.org/doc/html/rfc2045#section-6.8">RFC
4787 2045 Section 6.8</ulink>. As per the <acronym>RFC</acronym>, encoded lines are
4788 broken at 76 characters. However instead of the MIME CRLF
4789 end-of-line marker, only a newline is used for end-of-line.
4790 The <function>decode</function> function ignores carriage-return,
4791 newline, space, and tab characters. Otherwise, an error is
4792 raised when <function>decode</function> is supplied invalid
4793 base64 data &mdash; including when trailing padding is incorrect.
4794 </para>
4795 </listitem>
4796 </varlistentry>
4798 <varlistentry id="encode-format-escape">
4799 <term>escape
4800 <indexterm>
4801 <primary>escape format</primary>
4802 </indexterm></term>
4803 <listitem>
4804 <para>
4805 The <literal>escape</literal> format converts zero bytes and
4806 bytes with the high bit set into octal escape sequences
4807 (<literal>\</literal><replaceable>nnn</replaceable>), and it doubles
4808 backslashes. Other byte values are represented literally.
4809 The <function>decode</function> function will raise an error if a
4810 backslash is not followed by either a second backslash or three
4811 octal digits; it accepts other byte values unchanged.
4812 </para>
4813 </listitem>
4814 </varlistentry>
4816 <varlistentry id="encode-format-hex">
4817 <term>hex
4818 <indexterm>
4819 <primary>hex format</primary>
4820 </indexterm></term>
4821 <listitem>
4822 <para>
4823 The <literal>hex</literal> format represents each 4 bits of
4824 data as one hexadecimal digit, <literal>0</literal>
4825 through <literal>f</literal>, writing the higher-order digit of
4826 each byte first. The <function>encode</function> function outputs
4827 the <literal>a</literal>-<literal>f</literal> hex digits in lower
4828 case. Because the smallest unit of data is 8 bits, there are
4829 always an even number of characters returned
4830 by <function>encode</function>.
4831 The <function>decode</function> function
4832 accepts the <literal>a</literal>-<literal>f</literal> characters in
4833 either upper or lower case. An error is raised
4834 when <function>decode</function> is given invalid hex data
4835 &mdash; including when given an odd number of characters.
4836 </para>
4837 </listitem>
4838 </varlistentry>
4839 </variablelist>
4840 </para>
4842 <para>
4843 See also the aggregate function <function>string_agg</function> in
4844 <xref linkend="functions-aggregate"/> and the large object functions
4845 in <xref linkend="lo-funcs"/>.
4846 </para>
4847 </sect1>
4850 <sect1 id="functions-bitstring">
4851 <title>Bit String Functions and Operators</title>
4853 <indexterm zone="functions-bitstring">
4854 <primary>bit strings</primary>
4855 <secondary>functions</secondary>
4856 </indexterm>
4858 <para>
4859 This section describes functions and operators for examining and
4860 manipulating bit strings, that is values of the types
4861 <type>bit</type> and <type>bit varying</type>. (While only
4862 type <type>bit</type> is mentioned in these tables, values of
4863 type <type>bit varying</type> can be used interchangeably.)
4864 Bit strings support the usual comparison operators shown in
4865 <xref linkend="functions-comparison-op-table"/>, as well as the
4866 operators shown in <xref linkend="functions-bit-string-op-table"/>.
4867 </para>
4869 <table id="functions-bit-string-op-table">
4870 <title>Bit String Operators</title>
4871 <tgroup cols="1">
4872 <thead>
4873 <row>
4874 <entry role="func_table_entry"><para role="func_signature">
4875 Operator
4876 </para>
4877 <para>
4878 Description
4879 </para>
4880 <para>
4881 Example(s)
4882 </para></entry>
4883 </row>
4884 </thead>
4886 <tbody>
4887 <row>
4888 <entry role="func_table_entry"><para role="func_signature">
4889 <type>bit</type> <literal>||</literal> <type>bit</type>
4890 <returnvalue>bit</returnvalue>
4891 </para>
4892 <para>
4893 Concatenation
4894 </para>
4895 <para>
4896 <literal>B'10001' || B'011'</literal>
4897 <returnvalue>10001011</returnvalue>
4898 </para></entry>
4899 </row>
4901 <row>
4902 <entry role="func_table_entry"><para role="func_signature">
4903 <type>bit</type> <literal>&amp;</literal> <type>bit</type>
4904 <returnvalue>bit</returnvalue>
4905 </para>
4906 <para>
4907 Bitwise AND (inputs must be of equal length)
4908 </para>
4909 <para>
4910 <literal>B'10001' &amp; B'01101'</literal>
4911 <returnvalue>00001</returnvalue>
4912 </para></entry>
4913 </row>
4915 <row>
4916 <entry role="func_table_entry"><para role="func_signature">
4917 <type>bit</type> <literal>|</literal> <type>bit</type>
4918 <returnvalue>bit</returnvalue>
4919 </para>
4920 <para>
4921 Bitwise OR (inputs must be of equal length)
4922 </para>
4923 <para>
4924 <literal>B'10001' | B'01101'</literal>
4925 <returnvalue>11101</returnvalue>
4926 </para></entry>
4927 </row>
4929 <row>
4930 <entry role="func_table_entry"><para role="func_signature">
4931 <type>bit</type> <literal>#</literal> <type>bit</type>
4932 <returnvalue>bit</returnvalue>
4933 </para>
4934 <para>
4935 Bitwise exclusive OR (inputs must be of equal length)
4936 </para>
4937 <para>
4938 <literal>B'10001' # B'01101'</literal>
4939 <returnvalue>11100</returnvalue>
4940 </para></entry>
4941 </row>
4943 <row>
4944 <entry role="func_table_entry"><para role="func_signature">
4945 <literal>~</literal> <type>bit</type>
4946 <returnvalue>bit</returnvalue>
4947 </para>
4948 <para>
4949 Bitwise NOT
4950 </para>
4951 <para>
4952 <literal>~ B'10001'</literal>
4953 <returnvalue>01110</returnvalue>
4954 </para></entry>
4955 </row>
4957 <row>
4958 <entry role="func_table_entry"><para role="func_signature">
4959 <type>bit</type> <literal>&lt;&lt;</literal> <type>integer</type>
4960 <returnvalue>bit</returnvalue>
4961 </para>
4962 <para>
4963 Bitwise shift left
4964 (string length is preserved)
4965 </para>
4966 <para>
4967 <literal>B'10001' &lt;&lt; 3</literal>
4968 <returnvalue>01000</returnvalue>
4969 </para></entry>
4970 </row>
4972 <row>
4973 <entry role="func_table_entry"><para role="func_signature">
4974 <type>bit</type> <literal>&gt;&gt;</literal> <type>integer</type>
4975 <returnvalue>bit</returnvalue>
4976 </para>
4977 <para>
4978 Bitwise shift right
4979 (string length is preserved)
4980 </para>
4981 <para>
4982 <literal>B'10001' &gt;&gt; 2</literal>
4983 <returnvalue>00100</returnvalue>
4984 </para></entry>
4985 </row>
4986 </tbody>
4987 </tgroup>
4988 </table>
4990 <para>
4991 Some of the functions available for binary strings are also available
4992 for bit strings, as shown in <xref linkend="functions-bit-string-table"/>.
4993 </para>
4995 <table id="functions-bit-string-table">
4996 <title>Bit String Functions</title>
4997 <tgroup cols="1">
4998 <thead>
4999 <row>
5000 <entry role="func_table_entry"><para role="func_signature">
5001 Function
5002 </para>
5003 <para>
5004 Description
5005 </para>
5006 <para>
5007 Example(s)
5008 </para></entry>
5009 </row>
5010 </thead>
5012 <tbody>
5013 <row>
5014 <entry role="func_table_entry"><para role="func_signature">
5015 <indexterm>
5016 <primary>bit_count</primary>
5017 </indexterm>
5018 <function>bit_count</function> ( <type>bit</type> )
5019 <returnvalue>bigint</returnvalue>
5020 </para>
5021 <para>
5022 Returns the number of bits set in the bit string (also known as
5023 <quote>popcount</quote>).
5024 </para>
5025 <para>
5026 <literal>bit_count(B'10111')</literal>
5027 <returnvalue>4</returnvalue>
5028 </para></entry>
5029 </row>
5031 <row>
5032 <entry role="func_table_entry"><para role="func_signature">
5033 <indexterm>
5034 <primary>bit_length</primary>
5035 </indexterm>
5036 <function>bit_length</function> ( <type>bit</type> )
5037 <returnvalue>integer</returnvalue>
5038 </para>
5039 <para>
5040 Returns number of bits in the bit string.
5041 </para>
5042 <para>
5043 <literal>bit_length(B'10111')</literal>
5044 <returnvalue>5</returnvalue>
5045 </para></entry>
5046 </row>
5048 <row>
5049 <entry role="func_table_entry"><para role="func_signature">
5050 <indexterm>
5051 <primary>length</primary>
5052 </indexterm>
5053 <indexterm>
5054 <primary>bit string</primary>
5055 <secondary>length</secondary>
5056 </indexterm>
5057 <function>length</function> ( <type>bit</type> )
5058 <returnvalue>integer</returnvalue>
5059 </para>
5060 <para>
5061 Returns number of bits in the bit string.
5062 </para>
5063 <para>
5064 <literal>length(B'10111')</literal>
5065 <returnvalue>5</returnvalue>
5066 </para></entry>
5067 </row>
5069 <row>
5070 <entry role="func_table_entry"><para role="func_signature">
5071 <indexterm>
5072 <primary>octet_length</primary>
5073 </indexterm>
5074 <function>octet_length</function> ( <type>bit</type> )
5075 <returnvalue>integer</returnvalue>
5076 </para>
5077 <para>
5078 Returns number of bytes in the bit string.
5079 </para>
5080 <para>
5081 <literal>octet_length(B'1011111011')</literal>
5082 <returnvalue>2</returnvalue>
5083 </para></entry>
5084 </row>
5086 <row>
5087 <entry role="func_table_entry"><para role="func_signature">
5088 <indexterm>
5089 <primary>overlay</primary>
5090 </indexterm>
5091 <function>overlay</function> ( <parameter>bits</parameter> <type>bit</type> <literal>PLACING</literal> <parameter>newsubstring</parameter> <type>bit</type> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> )
5092 <returnvalue>bit</returnvalue>
5093 </para>
5094 <para>
5095 Replaces the substring of <parameter>bits</parameter> that starts at
5096 the <parameter>start</parameter>'th bit and extends
5097 for <parameter>count</parameter> bits
5098 with <parameter>newsubstring</parameter>.
5099 If <parameter>count</parameter> is omitted, it defaults to the length
5100 of <parameter>newsubstring</parameter>.
5101 </para>
5102 <para>
5103 <literal>overlay(B'01010101010101010' placing B'11111' from 2 for 3)</literal>
5104 <returnvalue>0111110101010101010</returnvalue>
5105 </para></entry>
5106 </row>
5108 <row>
5109 <entry role="func_table_entry"><para role="func_signature">
5110 <indexterm>
5111 <primary>position</primary>
5112 </indexterm>
5113 <function>position</function> ( <parameter>substring</parameter> <type>bit</type> <literal>IN</literal> <parameter>bits</parameter> <type>bit</type> )
5114 <returnvalue>integer</returnvalue>
5115 </para>
5116 <para>
5117 Returns first starting index of the specified <parameter>substring</parameter>
5118 within <parameter>bits</parameter>, or zero if it's not present.
5119 </para>
5120 <para>
5121 <literal>position(B'010' in B'000001101011')</literal>
5122 <returnvalue>8</returnvalue>
5123 </para></entry>
5124 </row>
5126 <row>
5127 <entry role="func_table_entry"><para role="func_signature">
5128 <indexterm>
5129 <primary>substring</primary>
5130 </indexterm>
5131 <function>substring</function> ( <parameter>bits</parameter> <type>bit</type> <optional> <literal>FROM</literal> <parameter>start</parameter> <type>integer</type> </optional> <optional> <literal>FOR</literal> <parameter>count</parameter> <type>integer</type> </optional> )
5132 <returnvalue>bit</returnvalue>
5133 </para>
5134 <para>
5135 Extracts the substring of <parameter>bits</parameter> starting at
5136 the <parameter>start</parameter>'th bit if that is specified,
5137 and stopping after <parameter>count</parameter> bits if that is
5138 specified. Provide at least one of <parameter>start</parameter>
5139 and <parameter>count</parameter>.
5140 </para>
5141 <para>
5142 <literal>substring(B'110010111111' from 3 for 2)</literal>
5143 <returnvalue>00</returnvalue>
5144 </para></entry>
5145 </row>
5147 <row>
5148 <entry role="func_table_entry"><para role="func_signature">
5149 <indexterm>
5150 <primary>get_bit</primary>
5151 </indexterm>
5152 <function>get_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5153 <parameter>n</parameter> <type>integer</type> )
5154 <returnvalue>integer</returnvalue>
5155 </para>
5156 <para>
5157 Extracts <parameter>n</parameter>'th bit
5158 from bit string; the first (leftmost) bit is bit 0.
5159 </para>
5160 <para>
5161 <literal>get_bit(B'101010101010101010', 6)</literal>
5162 <returnvalue>1</returnvalue>
5163 </para></entry>
5164 </row>
5166 <row>
5167 <entry role="func_table_entry"><para role="func_signature">
5168 <indexterm>
5169 <primary>set_bit</primary>
5170 </indexterm>
5171 <function>set_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5172 <parameter>n</parameter> <type>integer</type>,
5173 <parameter>newvalue</parameter> <type>integer</type> )
5174 <returnvalue>bit</returnvalue>
5175 </para>
5176 <para>
5177 Sets <parameter>n</parameter>'th bit in
5178 bit string to <parameter>newvalue</parameter>;
5179 the first (leftmost) bit is bit 0.
5180 </para>
5181 <para>
5182 <literal>set_bit(B'101010101010101010', 6, 0)</literal>
5183 <returnvalue>101010001010101010</returnvalue>
5184 </para></entry>
5185 </row>
5186 </tbody>
5187 </tgroup>
5188 </table>
5190 <para>
5191 In addition, it is possible to cast integral values to and from type
5192 <type>bit</type>.
5193 Casting an integer to <type>bit(n)</type> copies the rightmost
5194 <literal>n</literal> bits. Casting an integer to a bit string width wider
5195 than the integer itself will sign-extend on the left.
5196 Some examples:
5197 <programlisting>
5198 44::bit(10) <lineannotation>0000101100</lineannotation>
5199 44::bit(3) <lineannotation>100</lineannotation>
5200 cast(-44 as bit(12)) <lineannotation>111111010100</lineannotation>
5201 '1110'::bit(4)::integer <lineannotation>14</lineannotation>
5202 </programlisting>
5203 Note that casting to just <quote>bit</quote> means casting to
5204 <literal>bit(1)</literal>, and so will deliver only the least significant
5205 bit of the integer.
5206 </para>
5207 </sect1>
5210 <sect1 id="functions-matching">
5211 <title>Pattern Matching</title>
5213 <indexterm zone="functions-matching">
5214 <primary>pattern matching</primary>
5215 </indexterm>
5217 <para>
5218 There are three separate approaches to pattern matching provided
5219 by <productname>PostgreSQL</productname>: the traditional
5220 <acronym>SQL</acronym> <function>LIKE</function> operator, the
5221 more recent <function>SIMILAR TO</function> operator (added in
5222 SQL:1999), and <acronym>POSIX</acronym>-style regular
5223 expressions. Aside from the basic <quote>does this string match
5224 this pattern?</quote> operators, functions are available to extract
5225 or replace matching substrings and to split a string at matching
5226 locations.
5227 </para>
5229 <tip>
5230 <para>
5231 If you have pattern matching needs that go beyond this,
5232 consider writing a user-defined function in Perl or Tcl.
5233 </para>
5234 </tip>
5236 <caution>
5237 <para>
5238 While most regular-expression searches can be executed very quickly,
5239 regular expressions can be contrived that take arbitrary amounts of
5240 time and memory to process. Be wary of accepting regular-expression
5241 search patterns from hostile sources. If you must do so, it is
5242 advisable to impose a statement timeout.
5243 </para>
5245 <para>
5246 Searches using <function>SIMILAR TO</function> patterns have the same
5247 security hazards, since <function>SIMILAR TO</function> provides many
5248 of the same capabilities as <acronym>POSIX</acronym>-style regular
5249 expressions.
5250 </para>
5252 <para>
5253 <function>LIKE</function> searches, being much simpler than the other
5254 two options, are safer to use with possibly-hostile pattern sources.
5255 </para>
5256 </caution>
5258 <para>
5259 The pattern matching operators of all three kinds do not support
5260 nondeterministic collations. If required, apply a different collation to
5261 the expression to work around this limitation.
5262 </para>
5264 <sect2 id="functions-like">
5265 <title><function>LIKE</function></title>
5267 <indexterm>
5268 <primary>LIKE</primary>
5269 </indexterm>
5271 <synopsis>
5272 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5273 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5274 </synopsis>
5276 <para>
5277 The <function>LIKE</function> expression returns true if the
5278 <replaceable>string</replaceable> matches the supplied
5279 <replaceable>pattern</replaceable>. (As
5280 expected, the <function>NOT LIKE</function> expression returns
5281 false if <function>LIKE</function> returns true, and vice versa.
5282 An equivalent expression is
5283 <literal>NOT (<replaceable>string</replaceable> LIKE
5284 <replaceable>pattern</replaceable>)</literal>.)
5285 </para>
5287 <para>
5288 If <replaceable>pattern</replaceable> does not contain percent
5289 signs or underscores, then the pattern only represents the string
5290 itself; in that case <function>LIKE</function> acts like the
5291 equals operator. An underscore (<literal>_</literal>) in
5292 <replaceable>pattern</replaceable> stands for (matches) any single
5293 character; a percent sign (<literal>%</literal>) matches any sequence
5294 of zero or more characters.
5295 </para>
5297 <para>
5298 Some examples:
5299 <programlisting>
5300 'abc' LIKE 'abc' <lineannotation>true</lineannotation>
5301 'abc' LIKE 'a%' <lineannotation>true</lineannotation>
5302 'abc' LIKE '_b_' <lineannotation>true</lineannotation>
5303 'abc' LIKE 'c' <lineannotation>false</lineannotation>
5304 </programlisting>
5305 </para>
5307 <para>
5308 <function>LIKE</function> pattern matching always covers the entire
5309 string. Therefore, if it's desired to match a sequence anywhere within
5310 a string, the pattern must start and end with a percent sign.
5311 </para>
5313 <para>
5314 To match a literal underscore or percent sign without matching
5315 other characters, the respective character in
5316 <replaceable>pattern</replaceable> must be
5317 preceded by the escape character. The default escape
5318 character is the backslash but a different one can be selected by
5319 using the <literal>ESCAPE</literal> clause. To match the escape
5320 character itself, write two escape characters.
5321 </para>
5323 <note>
5324 <para>
5325 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
5326 any backslashes you write in literal string constants will need to be
5327 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
5328 </para>
5329 </note>
5331 <para>
5332 It's also possible to select no escape character by writing
5333 <literal>ESCAPE ''</literal>. This effectively disables the
5334 escape mechanism, which makes it impossible to turn off the
5335 special meaning of underscore and percent signs in the pattern.
5336 </para>
5338 <para>
5339 According to the SQL standard, omitting <literal>ESCAPE</literal>
5340 means there is no escape character (rather than defaulting to a
5341 backslash), and a zero-length <literal>ESCAPE</literal> value is
5342 disallowed. <productname>PostgreSQL</productname>'s behavior in
5343 this regard is therefore slightly nonstandard.
5344 </para>
5346 <para>
5347 The key word <token>ILIKE</token> can be used instead of
5348 <token>LIKE</token> to make the match case-insensitive according
5349 to the active locale. This is not in the <acronym>SQL</acronym> standard but is a
5350 <productname>PostgreSQL</productname> extension.
5351 </para>
5353 <para>
5354 The operator <literal>~~</literal> is equivalent to
5355 <function>LIKE</function>, and <literal>~~*</literal> corresponds to
5356 <function>ILIKE</function>. There are also
5357 <literal>!~~</literal> and <literal>!~~*</literal> operators that
5358 represent <function>NOT LIKE</function> and <function>NOT
5359 ILIKE</function>, respectively. All of these operators are
5360 <productname>PostgreSQL</productname>-specific. You may see these
5361 operator names in <command>EXPLAIN</command> output and similar
5362 places, since the parser actually translates <function>LIKE</function>
5363 et al. to these operators.
5364 </para>
5366 <para>
5367 The phrases <function>LIKE</function>, <function>ILIKE</function>,
5368 <function>NOT LIKE</function>, and <function>NOT ILIKE</function> are
5369 generally treated as operators
5370 in <productname>PostgreSQL</productname> syntax; for example they can
5371 be used in <replaceable>expression</replaceable>
5372 <replaceable>operator</replaceable> ANY
5373 (<replaceable>subquery</replaceable>) constructs, although
5374 an <literal>ESCAPE</literal> clause cannot be included there. In some
5375 obscure cases it may be necessary to use the underlying operator names
5376 instead.
5377 </para>
5379 <para>
5380 Also see the starts-with operator <literal>^@</literal> and the
5381 corresponding <function>starts_with()</function> function, which are
5382 useful in cases where simply matching the beginning of a string is
5383 needed.
5384 </para>
5385 </sect2>
5388 <sect2 id="functions-similarto-regexp">
5389 <title><function>SIMILAR TO</function> Regular Expressions</title>
5391 <indexterm>
5392 <primary>regular expression</primary>
5393 <!-- <seealso>pattern matching</seealso> breaks index build -->
5394 </indexterm>
5396 <indexterm>
5397 <primary>SIMILAR TO</primary>
5398 </indexterm>
5399 <indexterm>
5400 <primary>substring</primary>
5401 </indexterm>
5403 <synopsis>
5404 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5405 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5406 </synopsis>
5408 <para>
5409 The <function>SIMILAR TO</function> operator returns true or
5410 false depending on whether its pattern matches the given string.
5411 It is similar to <function>LIKE</function>, except that it
5412 interprets the pattern using the SQL standard's definition of a
5413 regular expression. SQL regular expressions are a curious cross
5414 between <function>LIKE</function> notation and common (POSIX) regular
5415 expression notation.
5416 </para>
5418 <para>
5419 Like <function>LIKE</function>, the <function>SIMILAR TO</function>
5420 operator succeeds only if its pattern matches the entire string;
5421 this is unlike common regular expression behavior where the pattern
5422 can match any part of the string.
5423 Also like
5424 <function>LIKE</function>, <function>SIMILAR TO</function> uses
5425 <literal>_</literal> and <literal>%</literal> as wildcard characters denoting
5426 any single character and any string, respectively (these are
5427 comparable to <literal>.</literal> and <literal>.*</literal> in POSIX regular
5428 expressions).
5429 </para>
5431 <para>
5432 In addition to these facilities borrowed from <function>LIKE</function>,
5433 <function>SIMILAR TO</function> supports these pattern-matching
5434 metacharacters borrowed from POSIX regular expressions:
5436 <itemizedlist>
5437 <listitem>
5438 <para>
5439 <literal>|</literal> denotes alternation (either of two alternatives).
5440 </para>
5441 </listitem>
5442 <listitem>
5443 <para>
5444 <literal>*</literal> denotes repetition of the previous item zero
5445 or more times.
5446 </para>
5447 </listitem>
5448 <listitem>
5449 <para>
5450 <literal>+</literal> denotes repetition of the previous item one
5451 or more times.
5452 </para>
5453 </listitem>
5454 <listitem>
5455 <para>
5456 <literal>?</literal> denotes repetition of the previous item zero
5457 or one time.
5458 </para>
5459 </listitem>
5460 <listitem>
5461 <para>
5462 <literal>{</literal><replaceable>m</replaceable><literal>}</literal> denotes repetition
5463 of the previous item exactly <replaceable>m</replaceable> times.
5464 </para>
5465 </listitem>
5466 <listitem>
5467 <para>
5468 <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> denotes repetition
5469 of the previous item <replaceable>m</replaceable> or more times.
5470 </para>
5471 </listitem>
5472 <listitem>
5473 <para>
5474 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
5475 denotes repetition of the previous item at least <replaceable>m</replaceable> and
5476 not more than <replaceable>n</replaceable> times.
5477 </para>
5478 </listitem>
5479 <listitem>
5480 <para>
5481 Parentheses <literal>()</literal> can be used to group items into
5482 a single logical item.
5483 </para>
5484 </listitem>
5485 <listitem>
5486 <para>
5487 A bracket expression <literal>[...]</literal> specifies a character
5488 class, just as in POSIX regular expressions.
5489 </para>
5490 </listitem>
5491 </itemizedlist>
5493 Notice that the period (<literal>.</literal>) is not a metacharacter
5494 for <function>SIMILAR TO</function>.
5495 </para>
5497 <para>
5498 As with <function>LIKE</function>, a backslash disables the special
5499 meaning of any of these metacharacters. A different escape character
5500 can be specified with <literal>ESCAPE</literal>, or the escape
5501 capability can be disabled by writing <literal>ESCAPE ''</literal>.
5502 </para>
5504 <para>
5505 According to the SQL standard, omitting <literal>ESCAPE</literal>
5506 means there is no escape character (rather than defaulting to a
5507 backslash), and a zero-length <literal>ESCAPE</literal> value is
5508 disallowed. <productname>PostgreSQL</productname>'s behavior in
5509 this regard is therefore slightly nonstandard.
5510 </para>
5512 <para>
5513 Another nonstandard extension is that following the escape character
5514 with a letter or digit provides access to the escape sequences
5515 defined for POSIX regular expressions; see
5516 <xref linkend="posix-character-entry-escapes-table"/>,
5517 <xref linkend="posix-class-shorthand-escapes-table"/>, and
5518 <xref linkend="posix-constraint-escapes-table"/> below.
5519 </para>
5521 <para>
5522 Some examples:
5523 <programlisting>
5524 'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation>
5525 'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation>
5526 'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation>
5527 'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation>
5528 '-abc-' SIMILAR TO '%\mabc\M%' <lineannotation>true</lineannotation>
5529 'xabcy' SIMILAR TO '%\mabc\M%' <lineannotation>false</lineannotation>
5530 </programlisting>
5531 </para>
5533 <para>
5534 The <function>substring</function> function with three parameters
5535 provides extraction of a substring that matches an SQL
5536 regular expression pattern. The function can be written according
5537 to standard SQL syntax:
5538 <synopsis>
5539 substring(<replaceable>string</replaceable> similar <replaceable>pattern</replaceable> escape <replaceable>escape-character</replaceable>)
5540 </synopsis>
5541 or using the now obsolete SQL:1999 syntax:
5542 <synopsis>
5543 substring(<replaceable>string</replaceable> from <replaceable>pattern</replaceable> for <replaceable>escape-character</replaceable>)
5544 </synopsis>
5545 or as a plain three-argument function:
5546 <synopsis>
5547 substring(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>escape-character</replaceable>)
5548 </synopsis>
5549 As with <literal>SIMILAR TO</literal>, the
5550 specified pattern must match the entire data string, or else the
5551 function fails and returns null. To indicate the part of the
5552 pattern for which the matching data sub-string is of interest,
5553 the pattern should contain
5554 two occurrences of the escape character followed by a double quote
5555 (<literal>"</literal>). <!-- " font-lock sanity -->
5556 The text matching the portion of the pattern
5557 between these separators is returned when the match is successful.
5558 </para>
5560 <para>
5561 The escape-double-quote separators actually
5562 divide <function>substring</function>'s pattern into three independent
5563 regular expressions; for example, a vertical bar (<literal>|</literal>)
5564 in any of the three sections affects only that section. Also, the first
5565 and third of these regular expressions are defined to match the smallest
5566 possible amount of text, not the largest, when there is any ambiguity
5567 about how much of the data string matches which pattern. (In POSIX
5568 parlance, the first and third regular expressions are forced to be
5569 non-greedy.)
5570 </para>
5572 <para>
5573 As an extension to the SQL standard, <productname>PostgreSQL</productname>
5574 allows there to be just one escape-double-quote separator, in which case
5575 the third regular expression is taken as empty; or no separators, in which
5576 case the first and third regular expressions are taken as empty.
5577 </para>
5579 <para>
5580 Some examples, with <literal>#&quot;</literal> delimiting the return string:
5581 <programlisting>
5582 substring('foobar' similar '%#"o_b#"%' escape '#') <lineannotation>oob</lineannotation>
5583 substring('foobar' similar '#"o_b#"%' escape '#') <lineannotation>NULL</lineannotation>
5584 </programlisting>
5585 </para>
5586 </sect2>
5588 <sect2 id="functions-posix-regexp">
5589 <title><acronym>POSIX</acronym> Regular Expressions</title>
5591 <indexterm zone="functions-posix-regexp">
5592 <primary>regular expression</primary>
5593 <seealso>pattern matching</seealso>
5594 </indexterm>
5595 <indexterm>
5596 <primary>substring</primary>
5597 </indexterm>
5598 <indexterm>
5599 <primary>regexp_count</primary>
5600 </indexterm>
5601 <indexterm>
5602 <primary>regexp_instr</primary>
5603 </indexterm>
5604 <indexterm>
5605 <primary>regexp_like</primary>
5606 </indexterm>
5607 <indexterm>
5608 <primary>regexp_match</primary>
5609 </indexterm>
5610 <indexterm>
5611 <primary>regexp_matches</primary>
5612 </indexterm>
5613 <indexterm>
5614 <primary>regexp_replace</primary>
5615 </indexterm>
5616 <indexterm>
5617 <primary>regexp_split_to_table</primary>
5618 </indexterm>
5619 <indexterm>
5620 <primary>regexp_split_to_array</primary>
5621 </indexterm>
5622 <indexterm>
5623 <primary>regexp_substr</primary>
5624 </indexterm>
5626 <para>
5627 <xref linkend="functions-posix-table"/> lists the available
5628 operators for pattern matching using POSIX regular expressions.
5629 </para>
5631 <table id="functions-posix-table">
5632 <title>Regular Expression Match Operators</title>
5634 <tgroup cols="1">
5635 <thead>
5636 <row>
5637 <entry role="func_table_entry"><para role="func_signature">
5638 Operator
5639 </para>
5640 <para>
5641 Description
5642 </para>
5643 <para>
5644 Example(s)
5645 </para></entry>
5646 </row>
5647 </thead>
5649 <tbody>
5650 <row>
5651 <entry role="func_table_entry"><para role="func_signature">
5652 <type>text</type> <literal>~</literal> <type>text</type>
5653 <returnvalue>boolean</returnvalue>
5654 </para>
5655 <para>
5656 String matches regular expression, case sensitively
5657 </para>
5658 <para>
5659 <literal>'thomas' ~ 't.*ma'</literal>
5660 <returnvalue>t</returnvalue>
5661 </para></entry>
5662 </row>
5664 <row>
5665 <entry role="func_table_entry"><para role="func_signature">
5666 <type>text</type> <literal>~*</literal> <type>text</type>
5667 <returnvalue>boolean</returnvalue>
5668 </para>
5669 <para>
5670 String matches regular expression, case-insensitively
5671 </para>
5672 <para>
5673 <literal>'thomas' ~* 'T.*ma'</literal>
5674 <returnvalue>t</returnvalue>
5675 </para></entry>
5676 </row>
5678 <row>
5679 <entry role="func_table_entry"><para role="func_signature">
5680 <type>text</type> <literal>!~</literal> <type>text</type>
5681 <returnvalue>boolean</returnvalue>
5682 </para>
5683 <para>
5684 String does not match regular expression, case sensitively
5685 </para>
5686 <para>
5687 <literal>'thomas' !~ 't.*max'</literal>
5688 <returnvalue>t</returnvalue>
5689 </para></entry>
5690 </row>
5692 <row>
5693 <entry role="func_table_entry"><para role="func_signature">
5694 <type>text</type> <literal>!~*</literal> <type>text</type>
5695 <returnvalue>boolean</returnvalue>
5696 </para>
5697 <para>
5698 String does not match regular expression, case-insensitively
5699 </para>
5700 <para>
5701 <literal>'thomas' !~* 'T.*ma'</literal>
5702 <returnvalue>f</returnvalue>
5703 </para></entry>
5704 </row>
5705 </tbody>
5706 </tgroup>
5707 </table>
5709 <para>
5710 <acronym>POSIX</acronym> regular expressions provide a more
5711 powerful means for pattern matching than the <function>LIKE</function> and
5712 <function>SIMILAR TO</function> operators.
5713 Many Unix tools such as <command>egrep</command>,
5714 <command>sed</command>, or <command>awk</command> use a pattern
5715 matching language that is similar to the one described here.
5716 </para>
5718 <para>
5719 A regular expression is a character sequence that is an
5720 abbreviated definition of a set of strings (a <firstterm>regular
5721 set</firstterm>). A string is said to match a regular expression
5722 if it is a member of the regular set described by the regular
5723 expression. As with <function>LIKE</function>, pattern characters
5724 match string characters exactly unless they are special characters
5725 in the regular expression language &mdash; but regular expressions use
5726 different special characters than <function>LIKE</function> does.
5727 Unlike <function>LIKE</function> patterns, a
5728 regular expression is allowed to match anywhere within a string, unless
5729 the regular expression is explicitly anchored to the beginning or
5730 end of the string.
5731 </para>
5733 <para>
5734 Some examples:
5735 <programlisting>
5736 'abcd' ~ 'bc' <lineannotation>true</lineannotation>
5737 'abcd' ~ 'a.c' <lineannotation>true &mdash; dot matches any character</lineannotation>
5738 'abcd' ~ 'a.*d' <lineannotation>true &mdash; <literal>*</literal> repeats the preceding pattern item</lineannotation>
5739 'abcd' ~ '(b|x)' <lineannotation>true &mdash; <literal>|</literal> means OR, parentheses group</lineannotation>
5740 'abcd' ~ '^a' <lineannotation>true &mdash; <literal>^</literal> anchors to start of string</lineannotation>
5741 'abcd' ~ '^(b|c)' <lineannotation>false &mdash; would match except for anchoring</lineannotation>
5742 </programlisting>
5743 </para>
5745 <para>
5746 The <acronym>POSIX</acronym> pattern language is described in much
5747 greater detail below.
5748 </para>
5750 <para>
5751 The <function>substring</function> function with two parameters,
5752 <function>substring(<replaceable>string</replaceable> from
5753 <replaceable>pattern</replaceable>)</function>, provides extraction of a
5754 substring
5755 that matches a POSIX regular expression pattern. It returns null if
5756 there is no match, otherwise the first portion of the text that matched the
5757 pattern. But if the pattern contains any parentheses, the portion
5758 of the text that matched the first parenthesized subexpression (the
5759 one whose left parenthesis comes first) is
5760 returned. You can put parentheses around the whole expression
5761 if you want to use parentheses within it without triggering this
5762 exception. If you need parentheses in the pattern before the
5763 subexpression you want to extract, see the non-capturing parentheses
5764 described below.
5765 </para>
5767 <para>
5768 Some examples:
5769 <programlisting>
5770 substring('foobar' from 'o.b') <lineannotation>oob</lineannotation>
5771 substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation>
5772 </programlisting>
5773 </para>
5775 <para>
5776 The <function>regexp_count</function> function counts the number of
5777 places where a POSIX regular expression pattern matches a string.
5778 It has the syntax
5779 <function>regexp_count</function>(<replaceable>string</replaceable>,
5780 <replaceable>pattern</replaceable>
5781 <optional>, <replaceable>start</replaceable>
5782 <optional>, <replaceable>flags</replaceable>
5783 </optional></optional>).
5784 <replaceable>pattern</replaceable> is searched for
5785 in <replaceable>string</replaceable>, normally from the beginning of
5786 the string, but if the <replaceable>start</replaceable> parameter is
5787 provided then beginning from that character index.
5788 The <replaceable>flags</replaceable> parameter is an optional text
5789 string containing zero or more single-letter flags that change the
5790 function's behavior. For example, including <literal>i</literal> in
5791 <replaceable>flags</replaceable> specifies case-insensitive matching.
5792 Supported flags are described in
5793 <xref linkend="posix-embedded-options-table"/>.
5794 </para>
5796 <para>
5797 Some examples:
5798 <programlisting>
5799 regexp_count('ABCABCAXYaxy', 'A.') <lineannotation>3</lineannotation>
5800 regexp_count('ABCABCAXYaxy', 'A.', 1, 'i') <lineannotation>4</lineannotation>
5801 </programlisting>
5802 </para>
5804 <para>
5805 The <function>regexp_instr</function> function returns the starting or
5806 ending position of the <replaceable>N</replaceable>'th match of a
5807 POSIX regular expression pattern to a string, or zero if there is no
5808 such match. It has the syntax
5809 <function>regexp_instr</function>(<replaceable>string</replaceable>,
5810 <replaceable>pattern</replaceable>
5811 <optional>, <replaceable>start</replaceable>
5812 <optional>, <replaceable>N</replaceable>
5813 <optional>, <replaceable>endoption</replaceable>
5814 <optional>, <replaceable>flags</replaceable>
5815 <optional>, <replaceable>subexpr</replaceable>
5816 </optional></optional></optional></optional></optional>).
5817 <replaceable>pattern</replaceable> is searched for
5818 in <replaceable>string</replaceable>, normally from the beginning of
5819 the string, but if the <replaceable>start</replaceable> parameter is
5820 provided then beginning from that character index.
5821 If <replaceable>N</replaceable> is specified
5822 then the <replaceable>N</replaceable>'th match of the pattern
5823 is located, otherwise the first match is located.
5824 If the <replaceable>endoption</replaceable> parameter is omitted or
5825 specified as zero, the function returns the position of the first
5826 character of the match. Otherwise, <replaceable>endoption</replaceable>
5827 must be one, and the function returns the position of the character
5828 following the match.
5829 The <replaceable>flags</replaceable> parameter is an optional text
5830 string containing zero or more single-letter flags that change the
5831 function's behavior. Supported flags are described
5832 in <xref linkend="posix-embedded-options-table"/>.
5833 For a pattern containing parenthesized
5834 subexpressions, <replaceable>subexpr</replaceable> is an integer
5835 indicating which subexpression is of interest: the result identifies
5836 the position of the substring matching that subexpression.
5837 Subexpressions are numbered in the order of their leading parentheses.
5838 When <replaceable>subexpr</replaceable> is omitted or zero, the result
5839 identifies the position of the whole match regardless of
5840 parenthesized subexpressions.
5841 </para>
5843 <para>
5844 Some examples:
5845 <programlisting>
5846 regexp_instr('number of your street, town zip, FR', '[^,]+', 1, 2)
5847 <lineannotation>23</lineannotation>
5848 regexp_instr('ABCDEFGHI', '(c..)(...)', 1, 1, 0, 'i', 2)
5849 <lineannotation>6</lineannotation>
5850 </programlisting>
5851 </para>
5853 <para>
5854 The <function>regexp_like</function> function checks whether a match
5855 of a POSIX regular expression pattern occurs within a string,
5856 returning boolean true or false. It has the syntax
5857 <function>regexp_like</function>(<replaceable>string</replaceable>,
5858 <replaceable>pattern</replaceable>
5859 <optional>, <replaceable>flags</replaceable> </optional>).
5860 The <replaceable>flags</replaceable> parameter is an optional text
5861 string containing zero or more single-letter flags that change the
5862 function's behavior. Supported flags are described
5863 in <xref linkend="posix-embedded-options-table"/>.
5864 This function has the same results as the <literal>~</literal>
5865 operator if no flags are specified. If only the <literal>i</literal>
5866 flag is specified, it has the same results as
5867 the <literal>~*</literal> operator.
5868 </para>
5870 <para>
5871 Some examples:
5872 <programlisting>
5873 regexp_like('Hello World', 'world') <lineannotation>false</lineannotation>
5874 regexp_like('Hello World', 'world', 'i') <lineannotation>true</lineannotation>
5875 </programlisting>
5876 </para>
5878 <para>
5879 The <function>regexp_match</function> function returns a text array of
5880 matching substring(s) within the first match of a POSIX
5881 regular expression pattern to a string. It has the syntax
5882 <function>regexp_match</function>(<replaceable>string</replaceable>,
5883 <replaceable>pattern</replaceable> <optional>, <replaceable>flags</replaceable> </optional>).
5884 If there is no match, the result is <literal>NULL</literal>.
5885 If a match is found, and the <replaceable>pattern</replaceable> contains no
5886 parenthesized subexpressions, then the result is a single-element text
5887 array containing the substring matching the whole pattern.
5888 If a match is found, and the <replaceable>pattern</replaceable> contains
5889 parenthesized subexpressions, then the result is a text array
5890 whose <replaceable>n</replaceable>'th element is the substring matching
5891 the <replaceable>n</replaceable>'th parenthesized subexpression of
5892 the <replaceable>pattern</replaceable> (not counting <quote>non-capturing</quote>
5893 parentheses; see below for details).
5894 The <replaceable>flags</replaceable> parameter is an optional text string
5895 containing zero or more single-letter flags that change the function's
5896 behavior. Supported flags are described
5897 in <xref linkend="posix-embedded-options-table"/>.
5898 </para>
5900 <para>
5901 Some examples:
5902 <programlisting>
5903 SELECT regexp_match('foobarbequebaz', 'bar.*que');
5904 regexp_match
5905 --------------
5906 {barbeque}
5907 (1 row)
5909 SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
5910 regexp_match
5911 --------------
5912 {bar,beque}
5913 (1 row)
5914 </programlisting>
5915 </para>
5917 <tip>
5918 <para>
5919 In the common case where you just want the whole matching substring
5920 or <literal>NULL</literal> for no match, the best solution is to
5921 use <function>regexp_substr()</function>.
5922 However, <function>regexp_substr()</function> only exists
5923 in <productname>PostgreSQL</productname> version 15 and up. When
5924 working in older versions, you can extract the first element
5925 of <function>regexp_match()</function>'s result, for example:
5926 <programlisting>
5927 SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[1];
5928 regexp_match
5929 --------------
5930 barbeque
5931 (1 row)
5932 </programlisting>
5933 </para>
5934 </tip>
5936 <para>
5937 The <function>regexp_matches</function> function returns a set of text arrays
5938 of matching substring(s) within matches of a POSIX regular
5939 expression pattern to a string. It has the same syntax as
5940 <function>regexp_match</function>.
5941 This function returns no rows if there is no match, one row if there is
5942 a match and the <literal>g</literal> flag is not given, or <replaceable>N</replaceable>
5943 rows if there are <replaceable>N</replaceable> matches and the <literal>g</literal> flag
5944 is given. Each returned row is a text array containing the whole
5945 matched substring or the substrings matching parenthesized
5946 subexpressions of the <replaceable>pattern</replaceable>, just as described above
5947 for <function>regexp_match</function>.
5948 <function>regexp_matches</function> accepts all the flags shown
5949 in <xref linkend="posix-embedded-options-table"/>, plus
5950 the <literal>g</literal> flag which commands it to return all matches, not
5951 just the first one.
5952 </para>
5954 <para>
5955 Some examples:
5956 <programlisting>
5957 SELECT regexp_matches('foo', 'not there');
5958 regexp_matches
5959 ----------------
5960 (0 rows)
5962 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
5963 regexp_matches
5964 ----------------
5965 {bar,beque}
5966 {bazil,barf}
5967 (2 rows)
5968 </programlisting>
5969 </para>
5971 <tip>
5972 <para>
5973 In most cases <function>regexp_matches()</function> should be used with
5974 the <literal>g</literal> flag, since if you only want the first match, it's
5975 easier and more efficient to use <function>regexp_match()</function>.
5976 However, <function>regexp_match()</function> only exists
5977 in <productname>PostgreSQL</productname> version 10 and up. When working in older
5978 versions, a common trick is to place a <function>regexp_matches()</function>
5979 call in a sub-select, for example:
5980 <programlisting>
5981 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
5982 </programlisting>
5983 This produces a text array if there's a match, or <literal>NULL</literal> if
5984 not, the same as <function>regexp_match()</function> would do. Without the
5985 sub-select, this query would produce no output at all for table rows
5986 without a match, which is typically not the desired behavior.
5987 </para>
5988 </tip>
5990 <para>
5991 The <function>regexp_replace</function> function provides substitution of
5992 new text for substrings that match POSIX regular expression patterns.
5993 It has the syntax
5994 <function>regexp_replace</function>(<replaceable>source</replaceable>,
5995 <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>
5996 <optional>, <replaceable>start</replaceable>
5997 <optional>, <replaceable>N</replaceable>
5998 </optional></optional>
5999 <optional>, <replaceable>flags</replaceable> </optional>).
6000 (Notice that <replaceable>N</replaceable> cannot be specified
6001 unless <replaceable>start</replaceable> is,
6002 but <replaceable>flags</replaceable> can be given in any case.)
6003 The <replaceable>source</replaceable> string is returned unchanged if
6004 there is no match to the <replaceable>pattern</replaceable>. If there is a
6005 match, the <replaceable>source</replaceable> string is returned with the
6006 <replaceable>replacement</replaceable> string substituted for the matching
6007 substring. The <replaceable>replacement</replaceable> string can contain
6008 <literal>\</literal><replaceable>n</replaceable>, where <replaceable>n</replaceable> is 1
6009 through 9, to indicate that the source substring matching the
6010 <replaceable>n</replaceable>'th parenthesized subexpression of the pattern should be
6011 inserted, and it can contain <literal>\&amp;</literal> to indicate that the
6012 substring matching the entire pattern should be inserted. Write
6013 <literal>\\</literal> if you need to put a literal backslash in the replacement
6014 text.
6015 <replaceable>pattern</replaceable> is searched for
6016 in <replaceable>string</replaceable>, normally from the beginning of
6017 the string, but if the <replaceable>start</replaceable> parameter is
6018 provided then beginning from that character index.
6019 By default, only the first match of the pattern is replaced.
6020 If <replaceable>N</replaceable> is specified and is greater than zero,
6021 then the <replaceable>N</replaceable>'th match of the pattern
6022 is replaced.
6023 If the <literal>g</literal> flag is given, or
6024 if <replaceable>N</replaceable> is specified and is zero, then all
6025 matches at or after the <replaceable>start</replaceable> position are
6026 replaced. (The <literal>g</literal> flag is ignored
6027 when <replaceable>N</replaceable> is specified.)
6028 The <replaceable>flags</replaceable> parameter is an optional text
6029 string containing zero or more single-letter flags that change the
6030 function's behavior. Supported flags (though
6031 not <literal>g</literal>) are
6032 described in <xref linkend="posix-embedded-options-table"/>.
6033 </para>
6035 <para>
6036 Some examples:
6037 <programlisting>
6038 regexp_replace('foobarbaz', 'b..', 'X')
6039 <lineannotation>fooXbaz</lineannotation>
6040 regexp_replace('foobarbaz', 'b..', 'X', 'g')
6041 <lineannotation>fooXX</lineannotation>
6042 regexp_replace('foobarbaz', 'b(..)', 'X\1Y', 'g')
6043 <lineannotation>fooXarYXazY</lineannotation>
6044 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 0, 'i')
6045 <lineannotation>X PXstgrXSQL fXnctXXn</lineannotation>
6046 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 3, 'i')
6047 <lineannotation>A PostgrXSQL function</lineannotation>
6048 </programlisting>
6049 </para>
6051 <para>
6052 The <function>regexp_split_to_table</function> function splits a string using a POSIX
6053 regular expression pattern as a delimiter. It has the syntax
6054 <function>regexp_split_to_table</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
6055 <optional>, <replaceable>flags</replaceable> </optional>).
6056 If there is no match to the <replaceable>pattern</replaceable>, the function returns the
6057 <replaceable>string</replaceable>. If there is at least one match, for each match it returns
6058 the text from the end of the last match (or the beginning of the string)
6059 to the beginning of the match. When there are no more matches, it
6060 returns the text from the end of the last match to the end of the string.
6061 The <replaceable>flags</replaceable> parameter is an optional text string containing
6062 zero or more single-letter flags that change the function's behavior.
6063 <function>regexp_split_to_table</function> supports the flags described in
6064 <xref linkend="posix-embedded-options-table"/>.
6065 </para>
6067 <para>
6068 The <function>regexp_split_to_array</function> function behaves the same as
6069 <function>regexp_split_to_table</function>, except that <function>regexp_split_to_array</function>
6070 returns its result as an array of <type>text</type>. It has the syntax
6071 <function>regexp_split_to_array</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
6072 <optional>, <replaceable>flags</replaceable> </optional>).
6073 The parameters are the same as for <function>regexp_split_to_table</function>.
6074 </para>
6076 <para>
6077 Some examples:
6078 <programlisting>
6079 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo;
6081 -------
6083 quick
6084 brown
6086 jumps
6087 over
6089 lazy
6091 (9 rows)
6093 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+');
6094 regexp_split_to_array
6095 -----------------------------------------------
6096 {the,quick,brown,fox,jumps,over,the,lazy,dog}
6097 (1 row)
6099 SELECT foo FROM regexp_split_to_table('the quick brown fox', '\s*') AS foo;
6101 -----
6118 (16 rows)
6119 </programlisting>
6120 </para>
6122 <para>
6123 As the last example demonstrates, the regexp split functions ignore
6124 zero-length matches that occur at the start or end of the string
6125 or immediately after a previous match. This is contrary to the strict
6126 definition of regexp matching that is implemented by
6127 the other regexp functions, but is usually the most convenient behavior
6128 in practice. Other software systems such as Perl use similar definitions.
6129 </para>
6131 <para>
6132 The <function>regexp_substr</function> function returns the substring
6133 that matches a POSIX regular expression pattern,
6134 or <literal>NULL</literal> if there is no match. It has the syntax
6135 <function>regexp_substr</function>(<replaceable>string</replaceable>,
6136 <replaceable>pattern</replaceable>
6137 <optional>, <replaceable>start</replaceable>
6138 <optional>, <replaceable>N</replaceable>
6139 <optional>, <replaceable>flags</replaceable>
6140 <optional>, <replaceable>subexpr</replaceable>
6141 </optional></optional></optional></optional>).
6142 <replaceable>pattern</replaceable> is searched for
6143 in <replaceable>string</replaceable>, normally from the beginning of
6144 the string, but if the <replaceable>start</replaceable> parameter is
6145 provided then beginning from that character index.
6146 If <replaceable>N</replaceable> is specified
6147 then the <replaceable>N</replaceable>'th match of the pattern
6148 is returned, otherwise the first match is returned.
6149 The <replaceable>flags</replaceable> parameter is an optional text
6150 string containing zero or more single-letter flags that change the
6151 function's behavior. Supported flags are described
6152 in <xref linkend="posix-embedded-options-table"/>.
6153 For a pattern containing parenthesized
6154 subexpressions, <replaceable>subexpr</replaceable> is an integer
6155 indicating which subexpression is of interest: the result is the
6156 substring matching that subexpression.
6157 Subexpressions are numbered in the order of their leading parentheses.
6158 When <replaceable>subexpr</replaceable> is omitted or zero, the result
6159 is the whole match regardless of parenthesized subexpressions.
6160 </para>
6162 <para>
6163 Some examples:
6164 <programlisting>
6165 regexp_substr('number of your street, town zip, FR', '[^,]+', 1, 2)
6166 <lineannotation> town zip</lineannotation>
6167 regexp_substr('ABCDEFGHI', '(c..)(...)', 1, 1, 'i', 2)
6168 <lineannotation>FGH</lineannotation>
6169 </programlisting>
6170 </para>
6172 <!-- derived from the re_syntax.n man page -->
6174 <sect3 id="posix-syntax-details">
6175 <title>Regular Expression Details</title>
6177 <para>
6178 <productname>PostgreSQL</productname>'s regular expressions are implemented
6179 using a software package written by Henry Spencer. Much of
6180 the description of regular expressions below is copied verbatim from his
6181 manual.
6182 </para>
6184 <para>
6185 Regular expressions (<acronym>RE</acronym>s), as defined in
6186 <acronym>POSIX</acronym> 1003.2, come in two forms:
6187 <firstterm>extended</firstterm> <acronym>RE</acronym>s or <acronym>ERE</acronym>s
6188 (roughly those of <command>egrep</command>), and
6189 <firstterm>basic</firstterm> <acronym>RE</acronym>s or <acronym>BRE</acronym>s
6190 (roughly those of <command>ed</command>).
6191 <productname>PostgreSQL</productname> supports both forms, and
6192 also implements some extensions
6193 that are not in the POSIX standard, but have become widely used
6194 due to their availability in programming languages such as Perl and Tcl.
6195 <acronym>RE</acronym>s using these non-POSIX extensions are called
6196 <firstterm>advanced</firstterm> <acronym>RE</acronym>s or <acronym>ARE</acronym>s
6197 in this documentation. AREs are almost an exact superset of EREs,
6198 but BREs have several notational incompatibilities (as well as being
6199 much more limited).
6200 We first describe the ARE and ERE forms, noting features that apply
6201 only to AREs, and then describe how BREs differ.
6202 </para>
6204 <note>
6205 <para>
6206 <productname>PostgreSQL</productname> always initially presumes that a regular
6207 expression follows the ARE rules. However, the more limited ERE or
6208 BRE rules can be chosen by prepending an <firstterm>embedded option</firstterm>
6209 to the RE pattern, as described in <xref linkend="posix-metasyntax"/>.
6210 This can be useful for compatibility with applications that expect
6211 exactly the <acronym>POSIX</acronym> 1003.2 rules.
6212 </para>
6213 </note>
6215 <para>
6216 A regular expression is defined as one or more
6217 <firstterm>branches</firstterm>, separated by
6218 <literal>|</literal>. It matches anything that matches one of the
6219 branches.
6220 </para>
6222 <para>
6223 A branch is zero or more <firstterm>quantified atoms</firstterm> or
6224 <firstterm>constraints</firstterm>, concatenated.
6225 It matches a match for the first, followed by a match for the second, etc.;
6226 an empty branch matches the empty string.
6227 </para>
6229 <para>
6230 A quantified atom is an <firstterm>atom</firstterm> possibly followed
6231 by a single <firstterm>quantifier</firstterm>.
6232 Without a quantifier, it matches a match for the atom.
6233 With a quantifier, it can match some number of matches of the atom.
6234 An <firstterm>atom</firstterm> can be any of the possibilities
6235 shown in <xref linkend="posix-atoms-table"/>.
6236 The possible quantifiers and their meanings are shown in
6237 <xref linkend="posix-quantifiers-table"/>.
6238 </para>
6240 <para>
6241 A <firstterm>constraint</firstterm> matches an empty string, but matches only when
6242 specific conditions are met. A constraint can be used where an atom
6243 could be used, except it cannot be followed by a quantifier.
6244 The simple constraints are shown in
6245 <xref linkend="posix-constraints-table"/>;
6246 some more constraints are described later.
6247 </para>
6250 <table id="posix-atoms-table">
6251 <title>Regular Expression Atoms</title>
6253 <tgroup cols="2">
6254 <thead>
6255 <row>
6256 <entry>Atom</entry>
6257 <entry>Description</entry>
6258 </row>
6259 </thead>
6261 <tbody>
6262 <row>
6263 <entry> <literal>(</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6264 <entry> (where <replaceable>re</replaceable> is any regular expression)
6265 matches a match for
6266 <replaceable>re</replaceable>, with the match noted for possible reporting </entry>
6267 </row>
6269 <row>
6270 <entry> <literal>(?:</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6271 <entry> as above, but the match is not noted for reporting
6272 (a <quote>non-capturing</quote> set of parentheses)
6273 (AREs only) </entry>
6274 </row>
6276 <row>
6277 <entry> <literal>.</literal> </entry>
6278 <entry> matches any single character </entry>
6279 </row>
6281 <row>
6282 <entry> <literal>[</literal><replaceable>chars</replaceable><literal>]</literal> </entry>
6283 <entry> a <firstterm>bracket expression</firstterm>,
6284 matching any one of the <replaceable>chars</replaceable> (see
6285 <xref linkend="posix-bracket-expressions"/> for more detail) </entry>
6286 </row>
6288 <row>
6289 <entry> <literal>\</literal><replaceable>k</replaceable> </entry>
6290 <entry> (where <replaceable>k</replaceable> is a non-alphanumeric character)
6291 matches that character taken as an ordinary character,
6292 e.g., <literal>\\</literal> matches a backslash character </entry>
6293 </row>
6295 <row>
6296 <entry> <literal>\</literal><replaceable>c</replaceable> </entry>
6297 <entry> where <replaceable>c</replaceable> is alphanumeric
6298 (possibly followed by other characters)
6299 is an <firstterm>escape</firstterm>, see <xref linkend="posix-escape-sequences"/>
6300 (AREs only; in EREs and BREs, this matches <replaceable>c</replaceable>) </entry>
6301 </row>
6303 <row>
6304 <entry> <literal>{</literal> </entry>
6305 <entry> when followed by a character other than a digit,
6306 matches the left-brace character <literal>{</literal>;
6307 when followed by a digit, it is the beginning of a
6308 <replaceable>bound</replaceable> (see below) </entry>
6309 </row>
6311 <row>
6312 <entry> <replaceable>x</replaceable> </entry>
6313 <entry> where <replaceable>x</replaceable> is a single character with no other
6314 significance, matches that character </entry>
6315 </row>
6316 </tbody>
6317 </tgroup>
6318 </table>
6320 <para>
6321 An RE cannot end with a backslash (<literal>\</literal>).
6322 </para>
6324 <note>
6325 <para>
6326 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
6327 any backslashes you write in literal string constants will need to be
6328 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
6329 </para>
6330 </note>
6332 <table id="posix-quantifiers-table">
6333 <title>Regular Expression Quantifiers</title>
6335 <tgroup cols="2">
6336 <thead>
6337 <row>
6338 <entry>Quantifier</entry>
6339 <entry>Matches</entry>
6340 </row>
6341 </thead>
6343 <tbody>
6344 <row>
6345 <entry> <literal>*</literal> </entry>
6346 <entry> a sequence of 0 or more matches of the atom </entry>
6347 </row>
6349 <row>
6350 <entry> <literal>+</literal> </entry>
6351 <entry> a sequence of 1 or more matches of the atom </entry>
6352 </row>
6354 <row>
6355 <entry> <literal>?</literal> </entry>
6356 <entry> a sequence of 0 or 1 matches of the atom </entry>
6357 </row>
6359 <row>
6360 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6361 <entry> a sequence of exactly <replaceable>m</replaceable> matches of the atom </entry>
6362 </row>
6364 <row>
6365 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6366 <entry> a sequence of <replaceable>m</replaceable> or more matches of the atom </entry>
6367 </row>
6369 <row>
6370 <entry>
6371 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6372 <entry> a sequence of <replaceable>m</replaceable> through <replaceable>n</replaceable>
6373 (inclusive) matches of the atom; <replaceable>m</replaceable> cannot exceed
6374 <replaceable>n</replaceable> </entry>
6375 </row>
6377 <row>
6378 <entry> <literal>*?</literal> </entry>
6379 <entry> non-greedy version of <literal>*</literal> </entry>
6380 </row>
6382 <row>
6383 <entry> <literal>+?</literal> </entry>
6384 <entry> non-greedy version of <literal>+</literal> </entry>
6385 </row>
6387 <row>
6388 <entry> <literal>??</literal> </entry>
6389 <entry> non-greedy version of <literal>?</literal> </entry>
6390 </row>
6392 <row>
6393 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}?</literal> </entry>
6394 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6395 </row>
6397 <row>
6398 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}?</literal> </entry>
6399 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6400 </row>
6402 <row>
6403 <entry>
6404 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal> </entry>
6405 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6406 </row>
6407 </tbody>
6408 </tgroup>
6409 </table>
6411 <para>
6412 The forms using <literal>{</literal><replaceable>...</replaceable><literal>}</literal>
6413 are known as <firstterm>bounds</firstterm>.
6414 The numbers <replaceable>m</replaceable> and <replaceable>n</replaceable> within a bound are
6415 unsigned decimal integers with permissible values from 0 to 255 inclusive.
6416 </para>
6418 <para>
6419 <firstterm>Non-greedy</firstterm> quantifiers (available in AREs only) match the
6420 same possibilities as their corresponding normal (<firstterm>greedy</firstterm>)
6421 counterparts, but prefer the smallest number rather than the largest
6422 number of matches.
6423 See <xref linkend="posix-matching-rules"/> for more detail.
6424 </para>
6426 <note>
6427 <para>
6428 A quantifier cannot immediately follow another quantifier, e.g.,
6429 <literal>**</literal> is invalid.
6430 A quantifier cannot
6431 begin an expression or subexpression or follow
6432 <literal>^</literal> or <literal>|</literal>.
6433 </para>
6434 </note>
6436 <table id="posix-constraints-table">
6437 <title>Regular Expression Constraints</title>
6439 <tgroup cols="2">
6440 <thead>
6441 <row>
6442 <entry>Constraint</entry>
6443 <entry>Description</entry>
6444 </row>
6445 </thead>
6447 <tbody>
6448 <row>
6449 <entry> <literal>^</literal> </entry>
6450 <entry> matches at the beginning of the string </entry>
6451 </row>
6453 <row>
6454 <entry> <literal>$</literal> </entry>
6455 <entry> matches at the end of the string </entry>
6456 </row>
6458 <row>
6459 <entry> <literal>(?=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6460 <entry> <firstterm>positive lookahead</firstterm> matches at any point
6461 where a substring matching <replaceable>re</replaceable> begins
6462 (AREs only) </entry>
6463 </row>
6465 <row>
6466 <entry> <literal>(?!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6467 <entry> <firstterm>negative lookahead</firstterm> matches at any point
6468 where no substring matching <replaceable>re</replaceable> begins
6469 (AREs only) </entry>
6470 </row>
6472 <row>
6473 <entry> <literal>(?&lt;=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6474 <entry> <firstterm>positive lookbehind</firstterm> matches at any point
6475 where a substring matching <replaceable>re</replaceable> ends
6476 (AREs only) </entry>
6477 </row>
6479 <row>
6480 <entry> <literal>(?&lt;!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6481 <entry> <firstterm>negative lookbehind</firstterm> matches at any point
6482 where no substring matching <replaceable>re</replaceable> ends
6483 (AREs only) </entry>
6484 </row>
6485 </tbody>
6486 </tgroup>
6487 </table>
6489 <para>
6490 Lookahead and lookbehind constraints cannot contain <firstterm>back
6491 references</firstterm> (see <xref linkend="posix-escape-sequences"/>),
6492 and all parentheses within them are considered non-capturing.
6493 </para>
6494 </sect3>
6496 <sect3 id="posix-bracket-expressions">
6497 <title>Bracket Expressions</title>
6499 <para>
6500 A <firstterm>bracket expression</firstterm> is a list of
6501 characters enclosed in <literal>[]</literal>. It normally matches
6502 any single character from the list (but see below). If the list
6503 begins with <literal>^</literal>, it matches any single character
6504 <emphasis>not</emphasis> from the rest of the list.
6505 If two characters
6506 in the list are separated by <literal>-</literal>, this is
6507 shorthand for the full range of characters between those two
6508 (inclusive) in the collating sequence,
6509 e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
6510 any decimal digit. It is illegal for two ranges to share an
6511 endpoint, e.g., <literal>a-c-e</literal>. Ranges are very
6512 collating-sequence-dependent, so portable programs should avoid
6513 relying on them.
6514 </para>
6516 <para>
6517 To include a literal <literal>]</literal> in the list, make it the
6518 first character (after <literal>^</literal>, if that is used). To
6519 include a literal <literal>-</literal>, make it the first or last
6520 character, or the second endpoint of a range. To use a literal
6521 <literal>-</literal> as the first endpoint of a range, enclose it
6522 in <literal>[.</literal> and <literal>.]</literal> to make it a
6523 collating element (see below). With the exception of these characters,
6524 some combinations using <literal>[</literal>
6525 (see next paragraphs), and escapes (AREs only), all other special
6526 characters lose their special significance within a bracket expression.
6527 In particular, <literal>\</literal> is not special when following
6528 ERE or BRE rules, though it is special (as introducing an escape)
6529 in AREs.
6530 </para>
6532 <para>
6533 Within a bracket expression, a collating element (a character, a
6534 multiple-character sequence that collates as if it were a single
6535 character, or a collating-sequence name for either) enclosed in
6536 <literal>[.</literal> and <literal>.]</literal> stands for the
6537 sequence of characters of that collating element. The sequence is
6538 treated as a single element of the bracket expression's list. This
6539 allows a bracket
6540 expression containing a multiple-character collating element to
6541 match more than one character, e.g., if the collating sequence
6542 includes a <literal>ch</literal> collating element, then the RE
6543 <literal>[[.ch.]]*c</literal> matches the first five characters of
6544 <literal>chchcc</literal>.
6545 </para>
6547 <note>
6548 <para>
6549 <productname>PostgreSQL</productname> currently does not support multi-character collating
6550 elements. This information describes possible future behavior.
6551 </para>
6552 </note>
6554 <para>
6555 Within a bracket expression, a collating element enclosed in
6556 <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
6557 class</firstterm>, standing for the sequences of characters of all collating
6558 elements equivalent to that one, including itself. (If there are
6559 no other equivalent collating elements, the treatment is as if the
6560 enclosing delimiters were <literal>[.</literal> and
6561 <literal>.]</literal>.) For example, if <literal>o</literal> and
6562 <literal>^</literal> are the members of an equivalence class, then
6563 <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
6564 <literal>[o^]</literal> are all synonymous. An equivalence class
6565 cannot be an endpoint of a range.
6566 </para>
6568 <para>
6569 Within a bracket expression, the name of a character class
6570 enclosed in <literal>[:</literal> and <literal>:]</literal> stands
6571 for the list of all characters belonging to that class. A character
6572 class cannot be used as an endpoint of a range.
6573 The <acronym>POSIX</acronym> standard defines these character class
6574 names:
6575 <literal>alnum</literal> (letters and numeric digits),
6576 <literal>alpha</literal> (letters),
6577 <literal>blank</literal> (space and tab),
6578 <literal>cntrl</literal> (control characters),
6579 <literal>digit</literal> (numeric digits),
6580 <literal>graph</literal> (printable characters except space),
6581 <literal>lower</literal> (lower-case letters),
6582 <literal>print</literal> (printable characters including space),
6583 <literal>punct</literal> (punctuation),
6584 <literal>space</literal> (any white space),
6585 <literal>upper</literal> (upper-case letters),
6586 and <literal>xdigit</literal> (hexadecimal digits).
6587 The behavior of these standard character classes is generally
6588 consistent across platforms for characters in the 7-bit ASCII set.
6589 Whether a given non-ASCII character is considered to belong to one
6590 of these classes depends on the <firstterm>collation</firstterm>
6591 that is used for the regular-expression function or operator
6592 (see <xref linkend="collation"/>), or by default on the
6593 database's <envar>LC_CTYPE</envar> locale setting (see
6594 <xref linkend="locale"/>). The classification of non-ASCII
6595 characters can vary across platforms even in similarly-named
6596 locales. (But the <literal>C</literal> locale never considers any
6597 non-ASCII characters to belong to any of these classes.)
6598 In addition to these standard character
6599 classes, <productname>PostgreSQL</productname> defines
6600 the <literal>word</literal> character class, which is the same as
6601 <literal>alnum</literal> plus the underscore (<literal>_</literal>)
6602 character, and
6603 the <literal>ascii</literal> character class, which contains exactly
6604 the 7-bit ASCII set.
6605 </para>
6607 <para>
6608 There are two special cases of bracket expressions: the bracket
6609 expressions <literal>[[:&lt;:]]</literal> and
6610 <literal>[[:&gt;:]]</literal> are constraints,
6611 matching empty strings at the beginning
6612 and end of a word respectively. A word is defined as a sequence
6613 of word characters that is neither preceded nor followed by word
6614 characters. A word character is any character belonging to the
6615 <literal>word</literal> character class, that is, any letter, digit,
6616 or underscore. This is an extension, compatible with but not
6617 specified by <acronym>POSIX</acronym> 1003.2, and should be used with
6618 caution in software intended to be portable to other systems.
6619 The constraint escapes described below are usually preferable; they
6620 are no more standard, but are easier to type.
6621 </para>
6622 </sect3>
6624 <sect3 id="posix-escape-sequences">
6625 <title>Regular Expression Escapes</title>
6627 <para>
6628 <firstterm>Escapes</firstterm> are special sequences beginning with <literal>\</literal>
6629 followed by an alphanumeric character. Escapes come in several varieties:
6630 character entry, class shorthands, constraint escapes, and back references.
6631 A <literal>\</literal> followed by an alphanumeric character but not constituting
6632 a valid escape is illegal in AREs.
6633 In EREs, there are no escapes: outside a bracket expression,
6634 a <literal>\</literal> followed by an alphanumeric character merely stands for
6635 that character as an ordinary character, and inside a bracket expression,
6636 <literal>\</literal> is an ordinary character.
6637 (The latter is the one actual incompatibility between EREs and AREs.)
6638 </para>
6640 <para>
6641 <firstterm>Character-entry escapes</firstterm> exist to make it easier to specify
6642 non-printing and other inconvenient characters in REs. They are
6643 shown in <xref linkend="posix-character-entry-escapes-table"/>.
6644 </para>
6646 <para>
6647 <firstterm>Class-shorthand escapes</firstterm> provide shorthands for certain
6648 commonly-used character classes. They are
6649 shown in <xref linkend="posix-class-shorthand-escapes-table"/>.
6650 </para>
6652 <para>
6653 A <firstterm>constraint escape</firstterm> is a constraint,
6654 matching the empty string if specific conditions are met,
6655 written as an escape. They are
6656 shown in <xref linkend="posix-constraint-escapes-table"/>.
6657 </para>
6659 <para>
6660 A <firstterm>back reference</firstterm> (<literal>\</literal><replaceable>n</replaceable>) matches the
6661 same string matched by the previous parenthesized subexpression specified
6662 by the number <replaceable>n</replaceable>
6663 (see <xref linkend="posix-constraint-backref-table"/>). For example,
6664 <literal>([bc])\1</literal> matches <literal>bb</literal> or <literal>cc</literal>
6665 but not <literal>bc</literal> or <literal>cb</literal>.
6666 The subexpression must entirely precede the back reference in the RE.
6667 Subexpressions are numbered in the order of their leading parentheses.
6668 Non-capturing parentheses do not define subexpressions.
6669 The back reference considers only the string characters matched by the
6670 referenced subexpression, not any constraints contained in it. For
6671 example, <literal>(^\d)\1</literal> will match <literal>22</literal>.
6672 </para>
6674 <table id="posix-character-entry-escapes-table">
6675 <title>Regular Expression Character-Entry Escapes</title>
6677 <tgroup cols="2">
6678 <thead>
6679 <row>
6680 <entry>Escape</entry>
6681 <entry>Description</entry>
6682 </row>
6683 </thead>
6685 <tbody>
6686 <row>
6687 <entry> <literal>\a</literal> </entry>
6688 <entry> alert (bell) character, as in C </entry>
6689 </row>
6691 <row>
6692 <entry> <literal>\b</literal> </entry>
6693 <entry> backspace, as in C </entry>
6694 </row>
6696 <row>
6697 <entry> <literal>\B</literal> </entry>
6698 <entry> synonym for backslash (<literal>\</literal>) to help reduce the need for backslash
6699 doubling </entry>
6700 </row>
6702 <row>
6703 <entry> <literal>\c</literal><replaceable>X</replaceable> </entry>
6704 <entry> (where <replaceable>X</replaceable> is any character) the character whose
6705 low-order 5 bits are the same as those of
6706 <replaceable>X</replaceable>, and whose other bits are all zero </entry>
6707 </row>
6709 <row>
6710 <entry> <literal>\e</literal> </entry>
6711 <entry> the character whose collating-sequence name
6712 is <literal>ESC</literal>,
6713 or failing that, the character with octal value <literal>033</literal> </entry>
6714 </row>
6716 <row>
6717 <entry> <literal>\f</literal> </entry>
6718 <entry> form feed, as in C </entry>
6719 </row>
6721 <row>
6722 <entry> <literal>\n</literal> </entry>
6723 <entry> newline, as in C </entry>
6724 </row>
6726 <row>
6727 <entry> <literal>\r</literal> </entry>
6728 <entry> carriage return, as in C </entry>
6729 </row>
6731 <row>
6732 <entry> <literal>\t</literal> </entry>
6733 <entry> horizontal tab, as in C </entry>
6734 </row>
6736 <row>
6737 <entry> <literal>\u</literal><replaceable>wxyz</replaceable> </entry>
6738 <entry> (where <replaceable>wxyz</replaceable> is exactly four hexadecimal digits)
6739 the character whose hexadecimal value is
6740 <literal>0x</literal><replaceable>wxyz</replaceable>
6741 </entry>
6742 </row>
6744 <row>
6745 <entry> <literal>\U</literal><replaceable>stuvwxyz</replaceable> </entry>
6746 <entry> (where <replaceable>stuvwxyz</replaceable> is exactly eight hexadecimal
6747 digits)
6748 the character whose hexadecimal value is
6749 <literal>0x</literal><replaceable>stuvwxyz</replaceable>
6750 </entry>
6751 </row>
6753 <row>
6754 <entry> <literal>\v</literal> </entry>
6755 <entry> vertical tab, as in C </entry>
6756 </row>
6758 <row>
6759 <entry> <literal>\x</literal><replaceable>hhh</replaceable> </entry>
6760 <entry> (where <replaceable>hhh</replaceable> is any sequence of hexadecimal
6761 digits)
6762 the character whose hexadecimal value is
6763 <literal>0x</literal><replaceable>hhh</replaceable>
6764 (a single character no matter how many hexadecimal digits are used)
6765 </entry>
6766 </row>
6768 <row>
6769 <entry> <literal>\0</literal> </entry>
6770 <entry> the character whose value is <literal>0</literal> (the null byte)</entry>
6771 </row>
6773 <row>
6774 <entry> <literal>\</literal><replaceable>xy</replaceable> </entry>
6775 <entry> (where <replaceable>xy</replaceable> is exactly two octal digits,
6776 and is not a <firstterm>back reference</firstterm>)
6777 the character whose octal value is
6778 <literal>0</literal><replaceable>xy</replaceable> </entry>
6779 </row>
6781 <row>
6782 <entry> <literal>\</literal><replaceable>xyz</replaceable> </entry>
6783 <entry> (where <replaceable>xyz</replaceable> is exactly three octal digits,
6784 and is not a <firstterm>back reference</firstterm>)
6785 the character whose octal value is
6786 <literal>0</literal><replaceable>xyz</replaceable> </entry>
6787 </row>
6788 </tbody>
6789 </tgroup>
6790 </table>
6792 <para>
6793 Hexadecimal digits are <literal>0</literal>-<literal>9</literal>,
6794 <literal>a</literal>-<literal>f</literal>, and <literal>A</literal>-<literal>F</literal>.
6795 Octal digits are <literal>0</literal>-<literal>7</literal>.
6796 </para>
6798 <para>
6799 Numeric character-entry escapes specifying values outside the ASCII range
6800 (0&ndash;127) have meanings dependent on the database encoding. When the
6801 encoding is UTF-8, escape values are equivalent to Unicode code points,
6802 for example <literal>\u1234</literal> means the character <literal>U+1234</literal>.
6803 For other multibyte encodings, character-entry escapes usually just
6804 specify the concatenation of the byte values for the character. If the
6805 escape value does not correspond to any legal character in the database
6806 encoding, no error will be raised, but it will never match any data.
6807 </para>
6809 <para>
6810 The character-entry escapes are always taken as ordinary characters.
6811 For example, <literal>\135</literal> is <literal>]</literal> in ASCII, but
6812 <literal>\135</literal> does not terminate a bracket expression.
6813 </para>
6815 <table id="posix-class-shorthand-escapes-table">
6816 <title>Regular Expression Class-Shorthand Escapes</title>
6818 <tgroup cols="2">
6819 <thead>
6820 <row>
6821 <entry>Escape</entry>
6822 <entry>Description</entry>
6823 </row>
6824 </thead>
6826 <tbody>
6827 <row>
6828 <entry> <literal>\d</literal> </entry>
6829 <entry> matches any digit, like
6830 <literal>[[:digit:]]</literal> </entry>
6831 </row>
6833 <row>
6834 <entry> <literal>\s</literal> </entry>
6835 <entry> matches any whitespace character, like
6836 <literal>[[:space:]]</literal> </entry>
6837 </row>
6839 <row>
6840 <entry> <literal>\w</literal> </entry>
6841 <entry> matches any word character, like
6842 <literal>[[:word:]]</literal> </entry>
6843 </row>
6845 <row>
6846 <entry> <literal>\D</literal> </entry>
6847 <entry> matches any non-digit, like
6848 <literal>[^[:digit:]]</literal> </entry>
6849 </row>
6851 <row>
6852 <entry> <literal>\S</literal> </entry>
6853 <entry> matches any non-whitespace character, like
6854 <literal>[^[:space:]]</literal> </entry>
6855 </row>
6857 <row>
6858 <entry> <literal>\W</literal> </entry>
6859 <entry> matches any non-word character, like
6860 <literal>[^[:word:]]</literal> </entry>
6861 </row>
6862 </tbody>
6863 </tgroup>
6864 </table>
6866 <para>
6867 The class-shorthand escapes also work within bracket expressions,
6868 although the definitions shown above are not quite syntactically
6869 valid in that context.
6870 For example, <literal>[a-c\d]</literal> is equivalent to
6871 <literal>[a-c[:digit:]]</literal>.
6872 </para>
6874 <table id="posix-constraint-escapes-table">
6875 <title>Regular Expression Constraint Escapes</title>
6877 <tgroup cols="2">
6878 <thead>
6879 <row>
6880 <entry>Escape</entry>
6881 <entry>Description</entry>
6882 </row>
6883 </thead>
6885 <tbody>
6886 <row>
6887 <entry> <literal>\A</literal> </entry>
6888 <entry> matches only at the beginning of the string
6889 (see <xref linkend="posix-matching-rules"/> for how this differs from
6890 <literal>^</literal>) </entry>
6891 </row>
6893 <row>
6894 <entry> <literal>\m</literal> </entry>
6895 <entry> matches only at the beginning of a word </entry>
6896 </row>
6898 <row>
6899 <entry> <literal>\M</literal> </entry>
6900 <entry> matches only at the end of a word </entry>
6901 </row>
6903 <row>
6904 <entry> <literal>\y</literal> </entry>
6905 <entry> matches only at the beginning or end of a word </entry>
6906 </row>
6908 <row>
6909 <entry> <literal>\Y</literal> </entry>
6910 <entry> matches only at a point that is not the beginning or end of a
6911 word </entry>
6912 </row>
6914 <row>
6915 <entry> <literal>\Z</literal> </entry>
6916 <entry> matches only at the end of the string
6917 (see <xref linkend="posix-matching-rules"/> for how this differs from
6918 <literal>$</literal>) </entry>
6919 </row>
6920 </tbody>
6921 </tgroup>
6922 </table>
6924 <para>
6925 A word is defined as in the specification of
6926 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal> above.
6927 Constraint escapes are illegal within bracket expressions.
6928 </para>
6930 <table id="posix-constraint-backref-table">
6931 <title>Regular Expression Back References</title>
6933 <tgroup cols="2">
6934 <thead>
6935 <row>
6936 <entry>Escape</entry>
6937 <entry>Description</entry>
6938 </row>
6939 </thead>
6941 <tbody>
6942 <row>
6943 <entry> <literal>\</literal><replaceable>m</replaceable> </entry>
6944 <entry> (where <replaceable>m</replaceable> is a nonzero digit)
6945 a back reference to the <replaceable>m</replaceable>'th subexpression </entry>
6946 </row>
6948 <row>
6949 <entry> <literal>\</literal><replaceable>mnn</replaceable> </entry>
6950 <entry> (where <replaceable>m</replaceable> is a nonzero digit, and
6951 <replaceable>nn</replaceable> is some more digits, and the decimal value
6952 <replaceable>mnn</replaceable> is not greater than the number of closing capturing
6953 parentheses seen so far)
6954 a back reference to the <replaceable>mnn</replaceable>'th subexpression </entry>
6955 </row>
6956 </tbody>
6957 </tgroup>
6958 </table>
6960 <note>
6961 <para>
6962 There is an inherent ambiguity between octal character-entry
6963 escapes and back references, which is resolved by the following heuristics,
6964 as hinted at above.
6965 A leading zero always indicates an octal escape.
6966 A single non-zero digit, not followed by another digit,
6967 is always taken as a back reference.
6968 A multi-digit sequence not starting with a zero is taken as a back
6969 reference if it comes after a suitable subexpression
6970 (i.e., the number is in the legal range for a back reference),
6971 and otherwise is taken as octal.
6972 </para>
6973 </note>
6974 </sect3>
6976 <sect3 id="posix-metasyntax">
6977 <title>Regular Expression Metasyntax</title>
6979 <para>
6980 In addition to the main syntax described above, there are some special
6981 forms and miscellaneous syntactic facilities available.
6982 </para>
6984 <para>
6985 An RE can begin with one of two special <firstterm>director</firstterm> prefixes.
6986 If an RE begins with <literal>***:</literal>,
6987 the rest of the RE is taken as an ARE. (This normally has no effect in
6988 <productname>PostgreSQL</productname>, since REs are assumed to be AREs;
6989 but it does have an effect if ERE or BRE mode had been specified by
6990 the <replaceable>flags</replaceable> parameter to a regex function.)
6991 If an RE begins with <literal>***=</literal>,
6992 the rest of the RE is taken to be a literal string,
6993 with all characters considered ordinary characters.
6994 </para>
6996 <para>
6997 An ARE can begin with <firstterm>embedded options</firstterm>:
6998 a sequence <literal>(?</literal><replaceable>xyz</replaceable><literal>)</literal>
6999 (where <replaceable>xyz</replaceable> is one or more alphabetic characters)
7000 specifies options affecting the rest of the RE.
7001 These options override any previously determined options &mdash;
7002 in particular, they can override the case-sensitivity behavior implied by
7003 a regex operator, or the <replaceable>flags</replaceable> parameter to a regex
7004 function.
7005 The available option letters are
7006 shown in <xref linkend="posix-embedded-options-table"/>.
7007 Note that these same option letters are used in the <replaceable>flags</replaceable>
7008 parameters of regex functions.
7009 </para>
7011 <table id="posix-embedded-options-table">
7012 <title>ARE Embedded-Option Letters</title>
7014 <tgroup cols="2">
7015 <thead>
7016 <row>
7017 <entry>Option</entry>
7018 <entry>Description</entry>
7019 </row>
7020 </thead>
7022 <tbody>
7023 <row>
7024 <entry> <literal>b</literal> </entry>
7025 <entry> rest of RE is a BRE </entry>
7026 </row>
7028 <row>
7029 <entry> <literal>c</literal> </entry>
7030 <entry> case-sensitive matching (overrides operator type) </entry>
7031 </row>
7033 <row>
7034 <entry> <literal>e</literal> </entry>
7035 <entry> rest of RE is an ERE </entry>
7036 </row>
7038 <row>
7039 <entry> <literal>i</literal> </entry>
7040 <entry> case-insensitive matching (see
7041 <xref linkend="posix-matching-rules"/>) (overrides operator type) </entry>
7042 </row>
7044 <row>
7045 <entry> <literal>m</literal> </entry>
7046 <entry> historical synonym for <literal>n</literal> </entry>
7047 </row>
7049 <row>
7050 <entry> <literal>n</literal> </entry>
7051 <entry> newline-sensitive matching (see
7052 <xref linkend="posix-matching-rules"/>) </entry>
7053 </row>
7055 <row>
7056 <entry> <literal>p</literal> </entry>
7057 <entry> partial newline-sensitive matching (see
7058 <xref linkend="posix-matching-rules"/>) </entry>
7059 </row>
7061 <row>
7062 <entry> <literal>q</literal> </entry>
7063 <entry> rest of RE is a literal (<quote>quoted</quote>) string, all ordinary
7064 characters </entry>
7065 </row>
7067 <row>
7068 <entry> <literal>s</literal> </entry>
7069 <entry> non-newline-sensitive matching (default) </entry>
7070 </row>
7072 <row>
7073 <entry> <literal>t</literal> </entry>
7074 <entry> tight syntax (default; see below) </entry>
7075 </row>
7077 <row>
7078 <entry> <literal>w</literal> </entry>
7079 <entry> inverse partial newline-sensitive (<quote>weird</quote>) matching
7080 (see <xref linkend="posix-matching-rules"/>) </entry>
7081 </row>
7083 <row>
7084 <entry> <literal>x</literal> </entry>
7085 <entry> expanded syntax (see below) </entry>
7086 </row>
7087 </tbody>
7088 </tgroup>
7089 </table>
7091 <para>
7092 Embedded options take effect at the <literal>)</literal> terminating the sequence.
7093 They can appear only at the start of an ARE (after the
7094 <literal>***:</literal> director if any).
7095 </para>
7097 <para>
7098 In addition to the usual (<firstterm>tight</firstterm>) RE syntax, in which all
7099 characters are significant, there is an <firstterm>expanded</firstterm> syntax,
7100 available by specifying the embedded <literal>x</literal> option.
7101 In the expanded syntax,
7102 white-space characters in the RE are ignored, as are
7103 all characters between a <literal>#</literal>
7104 and the following newline (or the end of the RE). This
7105 permits paragraphing and commenting a complex RE.
7106 There are three exceptions to that basic rule:
7108 <itemizedlist>
7109 <listitem>
7110 <para>
7111 a white-space character or <literal>#</literal> preceded by <literal>\</literal> is
7112 retained
7113 </para>
7114 </listitem>
7115 <listitem>
7116 <para>
7117 white space or <literal>#</literal> within a bracket expression is retained
7118 </para>
7119 </listitem>
7120 <listitem>
7121 <para>
7122 white space and comments cannot appear within multi-character symbols,
7123 such as <literal>(?:</literal>
7124 </para>
7125 </listitem>
7126 </itemizedlist>
7128 For this purpose, white-space characters are blank, tab, newline, and
7129 any character that belongs to the <replaceable>space</replaceable> character class.
7130 </para>
7132 <para>
7133 Finally, in an ARE, outside bracket expressions, the sequence
7134 <literal>(?#</literal><replaceable>ttt</replaceable><literal>)</literal>
7135 (where <replaceable>ttt</replaceable> is any text not containing a <literal>)</literal>)
7136 is a comment, completely ignored.
7137 Again, this is not allowed between the characters of
7138 multi-character symbols, like <literal>(?:</literal>.
7139 Such comments are more a historical artifact than a useful facility,
7140 and their use is deprecated; use the expanded syntax instead.
7141 </para>
7143 <para>
7144 <emphasis>None</emphasis> of these metasyntax extensions is available if
7145 an initial <literal>***=</literal> director
7146 has specified that the user's input be treated as a literal string
7147 rather than as an RE.
7148 </para>
7149 </sect3>
7151 <sect3 id="posix-matching-rules">
7152 <title>Regular Expression Matching Rules</title>
7154 <para>
7155 In the event that an RE could match more than one substring of a given
7156 string, the RE matches the one starting earliest in the string.
7157 If the RE could match more than one substring starting at that point,
7158 either the longest possible match or the shortest possible match will
7159 be taken, depending on whether the RE is <firstterm>greedy</firstterm> or
7160 <firstterm>non-greedy</firstterm>.
7161 </para>
7163 <para>
7164 Whether an RE is greedy or not is determined by the following rules:
7165 <itemizedlist>
7166 <listitem>
7167 <para>
7168 Most atoms, and all constraints, have no greediness attribute (because
7169 they cannot match variable amounts of text anyway).
7170 </para>
7171 </listitem>
7172 <listitem>
7173 <para>
7174 Adding parentheses around an RE does not change its greediness.
7175 </para>
7176 </listitem>
7177 <listitem>
7178 <para>
7179 A quantified atom with a fixed-repetition quantifier
7180 (<literal>{</literal><replaceable>m</replaceable><literal>}</literal>
7182 <literal>{</literal><replaceable>m</replaceable><literal>}?</literal>)
7183 has the same greediness (possibly none) as the atom itself.
7184 </para>
7185 </listitem>
7186 <listitem>
7187 <para>
7188 A quantified atom with other normal quantifiers (including
7189 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
7190 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7191 is greedy (prefers longest match).
7192 </para>
7193 </listitem>
7194 <listitem>
7195 <para>
7196 A quantified atom with a non-greedy quantifier (including
7197 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal>
7198 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7199 is non-greedy (prefers shortest match).
7200 </para>
7201 </listitem>
7202 <listitem>
7203 <para>
7204 A branch &mdash; that is, an RE that has no top-level
7205 <literal>|</literal> operator &mdash; has the same greediness as the first
7206 quantified atom in it that has a greediness attribute.
7207 </para>
7208 </listitem>
7209 <listitem>
7210 <para>
7211 An RE consisting of two or more branches connected by the
7212 <literal>|</literal> operator is always greedy.
7213 </para>
7214 </listitem>
7215 </itemizedlist>
7216 </para>
7218 <para>
7219 The above rules associate greediness attributes not only with individual
7220 quantified atoms, but with branches and entire REs that contain quantified
7221 atoms. What that means is that the matching is done in such a way that
7222 the branch, or whole RE, matches the longest or shortest possible
7223 substring <emphasis>as a whole</emphasis>. Once the length of the entire match
7224 is determined, the part of it that matches any particular subexpression
7225 is determined on the basis of the greediness attribute of that
7226 subexpression, with subexpressions starting earlier in the RE taking
7227 priority over ones starting later.
7228 </para>
7230 <para>
7231 An example of what this means:
7232 <screen>
7233 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
7234 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
7235 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
7236 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7237 </screen>
7238 In the first case, the RE as a whole is greedy because <literal>Y*</literal>
7239 is greedy. It can match beginning at the <literal>Y</literal>, and it matches
7240 the longest possible string starting there, i.e., <literal>Y123</literal>.
7241 The output is the parenthesized part of that, or <literal>123</literal>.
7242 In the second case, the RE as a whole is non-greedy because <literal>Y*?</literal>
7243 is non-greedy. It can match beginning at the <literal>Y</literal>, and it matches
7244 the shortest possible string starting there, i.e., <literal>Y1</literal>.
7245 The subexpression <literal>[0-9]{1,3}</literal> is greedy but it cannot change
7246 the decision as to the overall match length; so it is forced to match
7247 just <literal>1</literal>.
7248 </para>
7250 <para>
7251 In short, when an RE contains both greedy and non-greedy subexpressions,
7252 the total match length is either as long as possible or as short as
7253 possible, according to the attribute assigned to the whole RE. The
7254 attributes assigned to the subexpressions only affect how much of that
7255 match they are allowed to <quote>eat</quote> relative to each other.
7256 </para>
7258 <para>
7259 The quantifiers <literal>{1,1}</literal> and <literal>{1,1}?</literal>
7260 can be used to force greediness or non-greediness, respectively,
7261 on a subexpression or a whole RE.
7262 This is useful when you need the whole RE to have a greediness attribute
7263 different from what's deduced from its elements. As an example,
7264 suppose that we are trying to separate a string containing some digits
7265 into the digits and the parts before and after them. We might try to
7266 do that like this:
7267 <screen>
7268 SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
7269 <lineannotation>Result: </lineannotation><computeroutput>{abc0123,4,xyz}</computeroutput>
7270 </screen>
7271 That didn't work: the first <literal>.*</literal> is greedy so
7272 it <quote>eats</quote> as much as it can, leaving the <literal>\d+</literal> to
7273 match at the last possible place, the last digit. We might try to fix
7274 that by making it non-greedy:
7275 <screen>
7276 SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
7277 <lineannotation>Result: </lineannotation><computeroutput>{abc,0,""}</computeroutput>
7278 </screen>
7279 That didn't work either, because now the RE as a whole is non-greedy
7280 and so it ends the overall match as soon as possible. We can get what
7281 we want by forcing the RE as a whole to be greedy:
7282 <screen>
7283 SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
7284 <lineannotation>Result: </lineannotation><computeroutput>{abc,01234,xyz}</computeroutput>
7285 </screen>
7286 Controlling the RE's overall greediness separately from its components'
7287 greediness allows great flexibility in handling variable-length patterns.
7288 </para>
7290 <para>
7291 When deciding what is a longer or shorter match,
7292 match lengths are measured in characters, not collating elements.
7293 An empty string is considered longer than no match at all.
7294 For example:
7295 <literal>bb*</literal>
7296 matches the three middle characters of <literal>abbbc</literal>;
7297 <literal>(week|wee)(night|knights)</literal>
7298 matches all ten characters of <literal>weeknights</literal>;
7299 when <literal>(.*).*</literal>
7300 is matched against <literal>abc</literal> the parenthesized subexpression
7301 matches all three characters; and when
7302 <literal>(a*)*</literal> is matched against <literal>bc</literal>
7303 both the whole RE and the parenthesized
7304 subexpression match an empty string.
7305 </para>
7307 <para>
7308 If case-independent matching is specified,
7309 the effect is much as if all case distinctions had vanished from the
7310 alphabet.
7311 When an alphabetic that exists in multiple cases appears as an
7312 ordinary character outside a bracket expression, it is effectively
7313 transformed into a bracket expression containing both cases,
7314 e.g., <literal>x</literal> becomes <literal>[xX]</literal>.
7315 When it appears inside a bracket expression, all case counterparts
7316 of it are added to the bracket expression, e.g.,
7317 <literal>[x]</literal> becomes <literal>[xX]</literal>
7318 and <literal>[^x]</literal> becomes <literal>[^xX]</literal>.
7319 </para>
7321 <para>
7322 If newline-sensitive matching is specified, <literal>.</literal>
7323 and bracket expressions using <literal>^</literal>
7324 will never match the newline character
7325 (so that matches will not cross lines unless the RE
7326 explicitly includes a newline)
7327 and <literal>^</literal> and <literal>$</literal>
7328 will match the empty string after and before a newline
7329 respectively, in addition to matching at beginning and end of string
7330 respectively.
7331 But the ARE escapes <literal>\A</literal> and <literal>\Z</literal>
7332 continue to match beginning or end of string <emphasis>only</emphasis>.
7333 Also, the character class shorthands <literal>\D</literal>
7334 and <literal>\W</literal> will match a newline regardless of this mode.
7335 (Before <productname>PostgreSQL</productname> 14, they did not match
7336 newlines when in newline-sensitive mode.
7337 Write <literal>[^[:digit:]]</literal>
7338 or <literal>[^[:word:]]</literal> to get the old behavior.)
7339 </para>
7341 <para>
7342 If partial newline-sensitive matching is specified,
7343 this affects <literal>.</literal> and bracket expressions
7344 as with newline-sensitive matching, but not <literal>^</literal>
7345 and <literal>$</literal>.
7346 </para>
7348 <para>
7349 If inverse partial newline-sensitive matching is specified,
7350 this affects <literal>^</literal> and <literal>$</literal>
7351 as with newline-sensitive matching, but not <literal>.</literal>
7352 and bracket expressions.
7353 This isn't very useful but is provided for symmetry.
7354 </para>
7355 </sect3>
7357 <sect3 id="posix-limits-compatibility">
7358 <title>Limits and Compatibility</title>
7360 <para>
7361 No particular limit is imposed on the length of REs in this
7362 implementation. However,
7363 programs intended to be highly portable should not employ REs longer
7364 than 256 bytes,
7365 as a POSIX-compliant implementation can refuse to accept such REs.
7366 </para>
7368 <para>
7369 The only feature of AREs that is actually incompatible with
7370 POSIX EREs is that <literal>\</literal> does not lose its special
7371 significance inside bracket expressions.
7372 All other ARE features use syntax which is illegal or has
7373 undefined or unspecified effects in POSIX EREs;
7374 the <literal>***</literal> syntax of directors likewise is outside the POSIX
7375 syntax for both BREs and EREs.
7376 </para>
7378 <para>
7379 Many of the ARE extensions are borrowed from Perl, but some have
7380 been changed to clean them up, and a few Perl extensions are not present.
7381 Incompatibilities of note include <literal>\b</literal>, <literal>\B</literal>,
7382 the lack of special treatment for a trailing newline,
7383 the addition of complemented bracket expressions to the things
7384 affected by newline-sensitive matching,
7385 the restrictions on parentheses and back references in lookahead/lookbehind
7386 constraints, and the longest/shortest-match (rather than first-match)
7387 matching semantics.
7388 </para>
7389 </sect3>
7391 <sect3 id="posix-basic-regexes">
7392 <title>Basic Regular Expressions</title>
7394 <para>
7395 BREs differ from EREs in several respects.
7396 In BREs, <literal>|</literal>, <literal>+</literal>, and <literal>?</literal>
7397 are ordinary characters and there is no equivalent
7398 for their functionality.
7399 The delimiters for bounds are
7400 <literal>\{</literal> and <literal>\}</literal>,
7401 with <literal>{</literal> and <literal>}</literal>
7402 by themselves ordinary characters.
7403 The parentheses for nested subexpressions are
7404 <literal>\(</literal> and <literal>\)</literal>,
7405 with <literal>(</literal> and <literal>)</literal> by themselves ordinary characters.
7406 <literal>^</literal> is an ordinary character except at the beginning of the
7407 RE or the beginning of a parenthesized subexpression,
7408 <literal>$</literal> is an ordinary character except at the end of the
7409 RE or the end of a parenthesized subexpression,
7410 and <literal>*</literal> is an ordinary character if it appears at the beginning
7411 of the RE or the beginning of a parenthesized subexpression
7412 (after a possible leading <literal>^</literal>).
7413 Finally, single-digit back references are available, and
7414 <literal>\&lt;</literal> and <literal>\&gt;</literal>
7415 are synonyms for
7416 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal>
7417 respectively; no other escapes are available in BREs.
7418 </para>
7419 </sect3>
7421 <!-- end re_syntax.n man page -->
7423 <sect3 id="posix-vs-xquery">
7424 <title>Differences from SQL Standard and XQuery</title>
7426 <indexterm zone="posix-vs-xquery">
7427 <primary>LIKE_REGEX</primary>
7428 </indexterm>
7430 <indexterm zone="posix-vs-xquery">
7431 <primary>OCCURRENCES_REGEX</primary>
7432 </indexterm>
7434 <indexterm zone="posix-vs-xquery">
7435 <primary>POSITION_REGEX</primary>
7436 </indexterm>
7438 <indexterm zone="posix-vs-xquery">
7439 <primary>SUBSTRING_REGEX</primary>
7440 </indexterm>
7442 <indexterm zone="posix-vs-xquery">
7443 <primary>TRANSLATE_REGEX</primary>
7444 </indexterm>
7446 <indexterm zone="posix-vs-xquery">
7447 <primary>XQuery regular expressions</primary>
7448 </indexterm>
7450 <para>
7451 Since SQL:2008, the SQL standard includes regular expression operators
7452 and functions that performs pattern
7453 matching according to the XQuery regular expression
7454 standard:
7455 <itemizedlist>
7456 <listitem><para><literal>LIKE_REGEX</literal></para></listitem>
7457 <listitem><para><literal>OCCURRENCES_REGEX</literal></para></listitem>
7458 <listitem><para><literal>POSITION_REGEX</literal></para></listitem>
7459 <listitem><para><literal>SUBSTRING_REGEX</literal></para></listitem>
7460 <listitem><para><literal>TRANSLATE_REGEX</literal></para></listitem>
7461 </itemizedlist>
7462 <productname>PostgreSQL</productname> does not currently implement these
7463 operators and functions. You can get approximately equivalent
7464 functionality in each case as shown in <xref
7465 linkend="functions-regexp-sql-table"/>. (Various optional clauses on
7466 both sides have been omitted in this table.)
7467 </para>
7469 <table id="functions-regexp-sql-table">
7470 <title>Regular Expression Functions Equivalencies</title>
7472 <tgroup cols="2">
7473 <thead>
7474 <row>
7475 <entry>SQL standard</entry>
7476 <entry><productname>PostgreSQL</productname></entry>
7477 </row>
7478 </thead>
7480 <tbody>
7481 <row>
7482 <entry><literal><replaceable>string</replaceable> LIKE_REGEX <replaceable>pattern</replaceable></literal></entry>
7483 <entry><literal>regexp_like(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal> or <literal><replaceable>string</replaceable> ~ <replaceable>pattern</replaceable></literal></entry>
7484 </row>
7486 <row>
7487 <entry><literal>OCCURRENCES_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7488 <entry><literal>regexp_count(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7489 </row>
7491 <row>
7492 <entry><literal>POSITION_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7493 <entry><literal>regexp_instr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7494 </row>
7496 <row>
7497 <entry><literal>SUBSTRING_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7498 <entry><literal>regexp_substr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7499 </row>
7501 <row>
7502 <entry><literal>TRANSLATE_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable> WITH <replaceable>replacement</replaceable>)</literal></entry>
7503 <entry><literal>regexp_replace(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>)</literal></entry>
7504 </row>
7505 </tbody>
7506 </tgroup>
7507 </table>
7509 <para>
7510 Regular expression functions similar to those provided by PostgreSQL are
7511 also available in a number of other SQL implementations, whereas the
7512 SQL-standard functions are not as widely implemented. Some of the
7513 details of the regular expression syntax will likely differ in each
7514 implementation.
7515 </para>
7517 <para>
7518 The SQL-standard operators and functions use XQuery regular expressions,
7519 which are quite close to the ARE syntax described above.
7520 Notable differences between the existing POSIX-based
7521 regular-expression feature and XQuery regular expressions include:
7523 <itemizedlist>
7524 <listitem>
7525 <para>
7526 XQuery character class subtraction is not supported. An example of
7527 this feature is using the following to match only English
7528 consonants: <literal>[a-z-[aeiou]]</literal>.
7529 </para>
7530 </listitem>
7531 <listitem>
7532 <para>
7533 XQuery character class shorthands <literal>\c</literal>,
7534 <literal>\C</literal>, <literal>\i</literal>,
7535 and <literal>\I</literal> are not supported.
7536 </para>
7537 </listitem>
7538 <listitem>
7539 <para>
7540 XQuery character class elements
7541 using <literal>\p{UnicodeProperty}</literal> or the
7542 inverse <literal>\P{UnicodeProperty}</literal> are not supported.
7543 </para>
7544 </listitem>
7545 <listitem>
7546 <para>
7547 POSIX interprets character classes such as <literal>\w</literal>
7548 (see <xref linkend="posix-class-shorthand-escapes-table"/>)
7549 according to the prevailing locale (which you can control by
7550 attaching a <literal>COLLATE</literal> clause to the operator or
7551 function). XQuery specifies these classes by reference to Unicode
7552 character properties, so equivalent behavior is obtained only with
7553 a locale that follows the Unicode rules.
7554 </para>
7555 </listitem>
7556 <listitem>
7557 <para>
7558 The SQL standard (not XQuery itself) attempts to cater for more
7559 variants of <quote>newline</quote> than POSIX does. The
7560 newline-sensitive matching options described above consider only
7561 ASCII NL (<literal>\n</literal>) to be a newline, but SQL would have
7562 us treat CR (<literal>\r</literal>), CRLF (<literal>\r\n</literal>)
7563 (a Windows-style newline), and some Unicode-only characters like
7564 LINE SEPARATOR (U+2028) as newlines as well.
7565 Notably, <literal>.</literal> and <literal>\s</literal> should
7566 count <literal>\r\n</literal> as one character not two according to
7567 SQL.
7568 </para>
7569 </listitem>
7570 <listitem>
7571 <para>
7572 Of the character-entry escapes described in
7573 <xref linkend="posix-character-entry-escapes-table"/>,
7574 XQuery supports only <literal>\n</literal>, <literal>\r</literal>,
7575 and <literal>\t</literal>.
7576 </para>
7577 </listitem>
7578 <listitem>
7579 <para>
7580 XQuery does not support
7581 the <literal>[:<replaceable>name</replaceable>:]</literal> syntax
7582 for character classes within bracket expressions.
7583 </para>
7584 </listitem>
7585 <listitem>
7586 <para>
7587 XQuery does not have lookahead or lookbehind constraints,
7588 nor any of the constraint escapes described in
7589 <xref linkend="posix-constraint-escapes-table"/>.
7590 </para>
7591 </listitem>
7592 <listitem>
7593 <para>
7594 The metasyntax forms described in <xref linkend="posix-metasyntax"/>
7595 do not exist in XQuery.
7596 </para>
7597 </listitem>
7598 <listitem>
7599 <para>
7600 The regular expression flag letters defined by XQuery are
7601 related to but not the same as the option letters for POSIX
7602 (<xref linkend="posix-embedded-options-table"/>). While the
7603 <literal>i</literal> and <literal>q</literal> options behave the
7604 same, others do not:
7605 <itemizedlist>
7606 <listitem>
7607 <para>
7608 XQuery's <literal>s</literal> (allow dot to match newline)
7609 and <literal>m</literal> (allow <literal>^</literal>
7610 and <literal>$</literal> to match at newlines) flags provide
7611 access to the same behaviors as
7612 POSIX's <literal>n</literal>, <literal>p</literal>
7613 and <literal>w</literal> flags, but they
7614 do <emphasis>not</emphasis> match the behavior of
7615 POSIX's <literal>s</literal> and <literal>m</literal> flags.
7616 Note in particular that dot-matches-newline is the default
7617 behavior in POSIX but not XQuery.
7618 </para>
7619 </listitem>
7620 <listitem>
7621 <para>
7622 XQuery's <literal>x</literal> (ignore whitespace in pattern) flag
7623 is noticeably different from POSIX's expanded-mode flag.
7624 POSIX's <literal>x</literal> flag also
7625 allows <literal>#</literal> to begin a comment in the pattern,
7626 and POSIX will not ignore a whitespace character after a
7627 backslash.
7628 </para>
7629 </listitem>
7630 </itemizedlist>
7631 </para>
7632 </listitem>
7633 </itemizedlist>
7634 </para>
7636 </sect3>
7637 </sect2>
7638 </sect1>
7641 <sect1 id="functions-formatting">
7642 <title>Data Type Formatting Functions</title>
7644 <indexterm>
7645 <primary>formatting</primary>
7646 </indexterm>
7648 <para>
7649 The <productname>PostgreSQL</productname> formatting functions
7650 provide a powerful set of tools for converting various data types
7651 (date/time, integer, floating point, numeric) to formatted strings
7652 and for converting from formatted strings to specific data types.
7653 <xref linkend="functions-formatting-table"/> lists them.
7654 These functions all follow a common calling convention: the first
7655 argument is the value to be formatted and the second argument is a
7656 template that defines the output or input format.
7657 </para>
7659 <table id="functions-formatting-table">
7660 <title>Formatting Functions</title>
7661 <tgroup cols="1">
7662 <thead>
7663 <row>
7664 <entry role="func_table_entry"><para role="func_signature">
7665 Function
7666 </para>
7667 <para>
7668 Description
7669 </para>
7670 <para>
7671 Example(s)
7672 </para></entry>
7673 </row>
7674 </thead>
7676 <tbody>
7677 <row>
7678 <entry role="func_table_entry"><para role="func_signature">
7679 <indexterm>
7680 <primary>to_char</primary>
7681 </indexterm>
7682 <function>to_char</function> ( <type>timestamp</type>, <type>text</type> )
7683 <returnvalue>text</returnvalue>
7684 </para>
7685 <para role="func_signature">
7686 <function>to_char</function> ( <type>timestamp with time zone</type>, <type>text</type> )
7687 <returnvalue>text</returnvalue>
7688 </para>
7689 <para>
7690 Converts time stamp to string according to the given format.
7691 </para>
7692 <para>
7693 <literal>to_char(timestamp '2002-04-20 17:31:12.66', 'HH12:MI:SS')</literal>
7694 <returnvalue>05:31:12</returnvalue>
7695 </para></entry>
7696 </row>
7698 <row>
7699 <entry role="func_table_entry"><para role="func_signature">
7700 <function>to_char</function> ( <type>interval</type>, <type>text</type> )
7701 <returnvalue>text</returnvalue>
7702 </para>
7703 <para>
7704 Converts interval to string according to the given format.
7705 </para>
7706 <para>
7707 <literal>to_char(interval '15h 2m 12s', 'HH24:MI:SS')</literal>
7708 <returnvalue>15:02:12</returnvalue>
7709 </para></entry>
7710 </row>
7712 <row>
7713 <entry role="func_table_entry"><para role="func_signature">
7714 <function>to_char</function> ( <replaceable>numeric_type</replaceable>, <type>text</type> )
7715 <returnvalue>text</returnvalue>
7716 </para>
7717 <para>
7718 Converts number to string according to the given format; available
7719 for <type>integer</type>, <type>bigint</type>, <type>numeric</type>,
7720 <type>real</type>, <type>double precision</type>.
7721 </para>
7722 <para>
7723 <literal>to_char(125, '999')</literal>
7724 <returnvalue>125</returnvalue>
7725 </para>
7726 <para>
7727 <literal>to_char(125.8::real, '999D9')</literal>
7728 <returnvalue>125.8</returnvalue>
7729 </para>
7730 <para>
7731 <literal>to_char(-125.8, '999D99S')</literal>
7732 <returnvalue>125.80-</returnvalue>
7733 </para></entry>
7734 </row>
7736 <row>
7737 <entry role="func_table_entry"><para role="func_signature">
7738 <indexterm>
7739 <primary>to_date</primary>
7740 </indexterm>
7741 <function>to_date</function> ( <type>text</type>, <type>text</type> )
7742 <returnvalue>date</returnvalue>
7743 </para>
7744 <para>
7745 Converts string to date according to the given format.
7746 </para>
7747 <para>
7748 <literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal>
7749 <returnvalue>2000-12-05</returnvalue>
7750 </para></entry>
7751 </row>
7753 <row>
7754 <entry role="func_table_entry"><para role="func_signature">
7755 <indexterm>
7756 <primary>to_number</primary>
7757 </indexterm>
7758 <function>to_number</function> ( <type>text</type>, <type>text</type> )
7759 <returnvalue>numeric</returnvalue>
7760 </para>
7761 <para>
7762 Converts string to numeric according to the given format.
7763 </para>
7764 <para>
7765 <literal>to_number('12,454.8-', '99G999D9S')</literal>
7766 <returnvalue>-12454.8</returnvalue>
7767 </para></entry>
7768 </row>
7770 <row>
7771 <entry role="func_table_entry"><para role="func_signature">
7772 <indexterm>
7773 <primary>to_timestamp</primary>
7774 </indexterm>
7775 <function>to_timestamp</function> ( <type>text</type>, <type>text</type> )
7776 <returnvalue>timestamp with time zone</returnvalue>
7777 </para>
7778 <para>
7779 Converts string to time stamp according to the given format.
7780 (See also <function>to_timestamp(double precision)</function> in
7781 <xref linkend="functions-datetime-table"/>.)
7782 </para>
7783 <para>
7784 <literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal>
7785 <returnvalue>2000-12-05 00:00:00-05</returnvalue>
7786 </para></entry>
7787 </row>
7788 </tbody>
7789 </tgroup>
7790 </table>
7792 <tip>
7793 <para>
7794 <function>to_timestamp</function> and <function>to_date</function>
7795 exist to handle input formats that cannot be converted by
7796 simple casting. For most standard date/time formats, simply casting the
7797 source string to the required data type works, and is much easier.
7798 Similarly, <function>to_number</function> is unnecessary for standard numeric
7799 representations.
7800 </para>
7801 </tip>
7803 <para>
7804 In a <function>to_char</function> output template string, there are certain
7805 patterns that are recognized and replaced with appropriately-formatted
7806 data based on the given value. Any text that is not a template pattern is
7807 simply copied verbatim. Similarly, in an input template string (for the
7808 other functions), template patterns identify the values to be supplied by
7809 the input data string. If there are characters in the template string
7810 that are not template patterns, the corresponding characters in the input
7811 data string are simply skipped over (whether or not they are equal to the
7812 template string characters).
7813 </para>
7815 <para>
7816 <xref linkend="functions-formatting-datetime-table"/> shows the
7817 template patterns available for formatting date and time values.
7818 </para>
7820 <table id="functions-formatting-datetime-table">
7821 <title>Template Patterns for Date/Time Formatting</title>
7822 <tgroup cols="2">
7823 <thead>
7824 <row>
7825 <entry>Pattern</entry>
7826 <entry>Description</entry>
7827 </row>
7828 </thead>
7829 <tbody>
7830 <row>
7831 <entry><literal>HH</literal></entry>
7832 <entry>hour of day (01&ndash;12)</entry>
7833 </row>
7834 <row>
7835 <entry><literal>HH12</literal></entry>
7836 <entry>hour of day (01&ndash;12)</entry>
7837 </row>
7838 <row>
7839 <entry><literal>HH24</literal></entry>
7840 <entry>hour of day (00&ndash;23)</entry>
7841 </row>
7842 <row>
7843 <entry><literal>MI</literal></entry>
7844 <entry>minute (00&ndash;59)</entry>
7845 </row>
7846 <row>
7847 <entry><literal>SS</literal></entry>
7848 <entry>second (00&ndash;59)</entry>
7849 </row>
7850 <row>
7851 <entry><literal>MS</literal></entry>
7852 <entry>millisecond (000&ndash;999)</entry>
7853 </row>
7854 <row>
7855 <entry><literal>US</literal></entry>
7856 <entry>microsecond (000000&ndash;999999)</entry>
7857 </row>
7858 <row>
7859 <entry><literal>FF1</literal></entry>
7860 <entry>tenth of second (0&ndash;9)</entry>
7861 </row>
7862 <row>
7863 <entry><literal>FF2</literal></entry>
7864 <entry>hundredth of second (00&ndash;99)</entry>
7865 </row>
7866 <row>
7867 <entry><literal>FF3</literal></entry>
7868 <entry>millisecond (000&ndash;999)</entry>
7869 </row>
7870 <row>
7871 <entry><literal>FF4</literal></entry>
7872 <entry>tenth of a millisecond (0000&ndash;9999)</entry>
7873 </row>
7874 <row>
7875 <entry><literal>FF5</literal></entry>
7876 <entry>hundredth of a millisecond (00000&ndash;99999)</entry>
7877 </row>
7878 <row>
7879 <entry><literal>FF6</literal></entry>
7880 <entry>microsecond (000000&ndash;999999)</entry>
7881 </row>
7882 <row>
7883 <entry><literal>SSSS</literal>, <literal>SSSSS</literal></entry>
7884 <entry>seconds past midnight (0&ndash;86399)</entry>
7885 </row>
7886 <row>
7887 <entry><literal>AM</literal>, <literal>am</literal>,
7888 <literal>PM</literal> or <literal>pm</literal></entry>
7889 <entry>meridiem indicator (without periods)</entry>
7890 </row>
7891 <row>
7892 <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
7893 <literal>P.M.</literal> or <literal>p.m.</literal></entry>
7894 <entry>meridiem indicator (with periods)</entry>
7895 </row>
7896 <row>
7897 <entry><literal>Y,YYY</literal></entry>
7898 <entry>year (4 or more digits) with comma</entry>
7899 </row>
7900 <row>
7901 <entry><literal>YYYY</literal></entry>
7902 <entry>year (4 or more digits)</entry>
7903 </row>
7904 <row>
7905 <entry><literal>YYY</literal></entry>
7906 <entry>last 3 digits of year</entry>
7907 </row>
7908 <row>
7909 <entry><literal>YY</literal></entry>
7910 <entry>last 2 digits of year</entry>
7911 </row>
7912 <row>
7913 <entry><literal>Y</literal></entry>
7914 <entry>last digit of year</entry>
7915 </row>
7916 <row>
7917 <entry><literal>IYYY</literal></entry>
7918 <entry>ISO 8601 week-numbering year (4 or more digits)</entry>
7919 </row>
7920 <row>
7921 <entry><literal>IYY</literal></entry>
7922 <entry>last 3 digits of ISO 8601 week-numbering year</entry>
7923 </row>
7924 <row>
7925 <entry><literal>IY</literal></entry>
7926 <entry>last 2 digits of ISO 8601 week-numbering year</entry>
7927 </row>
7928 <row>
7929 <entry><literal>I</literal></entry>
7930 <entry>last digit of ISO 8601 week-numbering year</entry>
7931 </row>
7932 <row>
7933 <entry><literal>BC</literal>, <literal>bc</literal>,
7934 <literal>AD</literal> or <literal>ad</literal></entry>
7935 <entry>era indicator (without periods)</entry>
7936 </row>
7937 <row>
7938 <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
7939 <literal>A.D.</literal> or <literal>a.d.</literal></entry>
7940 <entry>era indicator (with periods)</entry>
7941 </row>
7942 <row>
7943 <entry><literal>MONTH</literal></entry>
7944 <entry>full upper case month name (blank-padded to 9 chars)</entry>
7945 </row>
7946 <row>
7947 <entry><literal>Month</literal></entry>
7948 <entry>full capitalized month name (blank-padded to 9 chars)</entry>
7949 </row>
7950 <row>
7951 <entry><literal>month</literal></entry>
7952 <entry>full lower case month name (blank-padded to 9 chars)</entry>
7953 </row>
7954 <row>
7955 <entry><literal>MON</literal></entry>
7956 <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
7957 </row>
7958 <row>
7959 <entry><literal>Mon</literal></entry>
7960 <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
7961 </row>
7962 <row>
7963 <entry><literal>mon</literal></entry>
7964 <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
7965 </row>
7966 <row>
7967 <entry><literal>MM</literal></entry>
7968 <entry>month number (01&ndash;12)</entry>
7969 </row>
7970 <row>
7971 <entry><literal>DAY</literal></entry>
7972 <entry>full upper case day name (blank-padded to 9 chars)</entry>
7973 </row>
7974 <row>
7975 <entry><literal>Day</literal></entry>
7976 <entry>full capitalized day name (blank-padded to 9 chars)</entry>
7977 </row>
7978 <row>
7979 <entry><literal>day</literal></entry>
7980 <entry>full lower case day name (blank-padded to 9 chars)</entry>
7981 </row>
7982 <row>
7983 <entry><literal>DY</literal></entry>
7984 <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
7985 </row>
7986 <row>
7987 <entry><literal>Dy</literal></entry>
7988 <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
7989 </row>
7990 <row>
7991 <entry><literal>dy</literal></entry>
7992 <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
7993 </row>
7994 <row>
7995 <entry><literal>DDD</literal></entry>
7996 <entry>day of year (001&ndash;366)</entry>
7997 </row>
7998 <row>
7999 <entry><literal>IDDD</literal></entry>
8000 <entry>day of ISO 8601 week-numbering year (001&ndash;371; day 1 of the year is Monday of the first ISO week)</entry>
8001 </row>
8002 <row>
8003 <entry><literal>DD</literal></entry>
8004 <entry>day of month (01&ndash;31)</entry>
8005 </row>
8006 <row>
8007 <entry><literal>D</literal></entry>
8008 <entry>day of the week, Sunday (<literal>1</literal>) to Saturday (<literal>7</literal>)</entry>
8009 </row>
8010 <row>
8011 <entry><literal>ID</literal></entry>
8012 <entry>ISO 8601 day of the week, Monday (<literal>1</literal>) to Sunday (<literal>7</literal>)</entry>
8013 </row>
8014 <row>
8015 <entry><literal>W</literal></entry>
8016 <entry>week of month (1&ndash;5) (the first week starts on the first day of the month)</entry>
8017 </row>
8018 <row>
8019 <entry><literal>WW</literal></entry>
8020 <entry>week number of year (1&ndash;53) (the first week starts on the first day of the year)</entry>
8021 </row>
8022 <row>
8023 <entry><literal>IW</literal></entry>
8024 <entry>week number of ISO 8601 week-numbering year (01&ndash;53; the first Thursday of the year is in week 1)</entry>
8025 </row>
8026 <row>
8027 <entry><literal>CC</literal></entry>
8028 <entry>century (2 digits) (the twenty-first century starts on 2001-01-01)</entry>
8029 </row>
8030 <row>
8031 <entry><literal>J</literal></entry>
8032 <entry>Julian Date (integer days since November 24, 4714 BC at local
8033 midnight; see <xref linkend="datetime-julian-dates"/>)</entry>
8034 </row>
8035 <row>
8036 <entry><literal>Q</literal></entry>
8037 <entry>quarter</entry>
8038 </row>
8039 <row>
8040 <entry><literal>RM</literal></entry>
8041 <entry>month in upper case Roman numerals (I&ndash;XII; I=January)</entry>
8042 </row>
8043 <row>
8044 <entry><literal>rm</literal></entry>
8045 <entry>month in lower case Roman numerals (i&ndash;xii; i=January)</entry>
8046 </row>
8047 <row>
8048 <entry><literal>TZ</literal></entry>
8049 <entry>upper case time-zone abbreviation
8050 (only supported in <function>to_char</function>)</entry>
8051 </row>
8052 <row>
8053 <entry><literal>tz</literal></entry>
8054 <entry>lower case time-zone abbreviation
8055 (only supported in <function>to_char</function>)</entry>
8056 </row>
8057 <row>
8058 <entry><literal>TZH</literal></entry>
8059 <entry>time-zone hours</entry>
8060 </row>
8061 <row>
8062 <entry><literal>TZM</literal></entry>
8063 <entry>time-zone minutes</entry>
8064 </row>
8065 <row>
8066 <entry><literal>OF</literal></entry>
8067 <entry>time-zone offset from UTC
8068 (only supported in <function>to_char</function>)</entry>
8069 </row>
8070 </tbody>
8071 </tgroup>
8072 </table>
8074 <para>
8075 Modifiers can be applied to any template pattern to alter its
8076 behavior. For example, <literal>FMMonth</literal>
8077 is the <literal>Month</literal> pattern with the
8078 <literal>FM</literal> modifier.
8079 <xref linkend="functions-formatting-datetimemod-table"/> shows the
8080 modifier patterns for date/time formatting.
8081 </para>
8083 <table id="functions-formatting-datetimemod-table">
8084 <title>Template Pattern Modifiers for Date/Time Formatting</title>
8085 <tgroup cols="3">
8086 <thead>
8087 <row>
8088 <entry>Modifier</entry>
8089 <entry>Description</entry>
8090 <entry>Example</entry>
8091 </row>
8092 </thead>
8093 <tbody>
8094 <row>
8095 <entry><literal>FM</literal> prefix</entry>
8096 <entry>fill mode (suppress leading zeroes and padding blanks)</entry>
8097 <entry><literal>FMMonth</literal></entry>
8098 </row>
8099 <row>
8100 <entry><literal>TH</literal> suffix</entry>
8101 <entry>upper case ordinal number suffix</entry>
8102 <entry><literal>DDTH</literal>, e.g., <literal>12TH</literal></entry>
8103 </row>
8104 <row>
8105 <entry><literal>th</literal> suffix</entry>
8106 <entry>lower case ordinal number suffix</entry>
8107 <entry><literal>DDth</literal>, e.g., <literal>12th</literal></entry>
8108 </row>
8109 <row>
8110 <entry><literal>FX</literal> prefix</entry>
8111 <entry>fixed format global option (see usage notes)</entry>
8112 <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
8113 </row>
8114 <row>
8115 <entry><literal>TM</literal> prefix</entry>
8116 <entry>translation mode (use localized day and month names based on
8117 <xref linkend="guc-lc-time"/>)</entry>
8118 <entry><literal>TMMonth</literal></entry>
8119 </row>
8120 <row>
8121 <entry><literal>SP</literal> suffix</entry>
8122 <entry>spell mode (not implemented)</entry>
8123 <entry><literal>DDSP</literal></entry>
8124 </row>
8125 </tbody>
8126 </tgroup>
8127 </table>
8129 <para>
8130 Usage notes for date/time formatting:
8132 <itemizedlist>
8133 <listitem>
8134 <para>
8135 <literal>FM</literal> suppresses leading zeroes and trailing blanks
8136 that would otherwise be added to make the output of a pattern be
8137 fixed-width. In <productname>PostgreSQL</productname>,
8138 <literal>FM</literal> modifies only the next specification, while in
8139 Oracle <literal>FM</literal> affects all subsequent
8140 specifications, and repeated <literal>FM</literal> modifiers
8141 toggle fill mode on and off.
8142 </para>
8143 </listitem>
8145 <listitem>
8146 <para>
8147 <literal>TM</literal> suppresses trailing blanks whether or
8148 not <literal>FM</literal> is specified.
8149 </para>
8150 </listitem>
8152 <listitem>
8153 <para>
8154 <function>to_timestamp</function> and <function>to_date</function>
8155 ignore letter case in the input; so for
8156 example <literal>MON</literal>, <literal>Mon</literal>,
8157 and <literal>mon</literal> all accept the same strings. When using
8158 the <literal>TM</literal> modifier, case-folding is done according to
8159 the rules of the function's input collation (see
8160 <xref linkend="collation"/>).
8161 </para>
8162 </listitem>
8164 <listitem>
8165 <para>
8166 <function>to_timestamp</function> and <function>to_date</function>
8167 skip multiple blank spaces at the beginning of the input string and
8168 around date and time values unless the <literal>FX</literal> option is used. For example,
8169 <literal>to_timestamp('&nbsp;2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> and
8170 <literal>to_timestamp('2000 - JUN', 'YYYY-MON')</literal> work, but
8171 <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
8172 because <function>to_timestamp</function> expects only a single space.
8173 <literal>FX</literal> must be specified as the first item in
8174 the template.
8175 </para>
8176 </listitem>
8178 <listitem>
8179 <para>
8180 A separator (a space or non-letter/non-digit character) in the template string of
8181 <function>to_timestamp</function> and <function>to_date</function>
8182 matches any single separator in the input string or is skipped,
8183 unless the <literal>FX</literal> option is used.
8184 For example, <literal>to_timestamp('2000JUN', 'YYYY///MON')</literal> and
8185 <literal>to_timestamp('2000/JUN', 'YYYY MON')</literal> work, but
8186 <literal>to_timestamp('2000//JUN', 'YYYY/MON')</literal>
8187 returns an error because the number of separators in the input string
8188 exceeds the number of separators in the template.
8189 </para>
8190 <para>
8191 If <literal>FX</literal> is specified, a separator in the template string
8192 matches exactly one character in the input string. But note that the
8193 input string character is not required to be the same as the separator from the template string.
8194 For example, <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal>
8195 works, but <literal>to_timestamp('2000/JUN', 'FXYYYY&nbsp;&nbsp;MON')</literal>
8196 returns an error because the second space in the template string consumes
8197 the letter <literal>J</literal> from the input string.
8198 </para>
8199 </listitem>
8201 <listitem>
8202 <para>
8203 A <literal>TZH</literal> template pattern can match a signed number.
8204 Without the <literal>FX</literal> option, minus signs may be ambiguous,
8205 and could be interpreted as a separator.
8206 This ambiguity is resolved as follows: If the number of separators before
8207 <literal>TZH</literal> in the template string is less than the number of
8208 separators before the minus sign in the input string, the minus sign
8209 is interpreted as part of <literal>TZH</literal>.
8210 Otherwise, the minus sign is considered to be a separator between values.
8211 For example, <literal>to_timestamp('2000 -10', 'YYYY TZH')</literal> matches
8212 <literal>-10</literal> to <literal>TZH</literal>, but
8213 <literal>to_timestamp('2000 -10', 'YYYY&nbsp;&nbsp;TZH')</literal>
8214 matches <literal>10</literal> to <literal>TZH</literal>.
8215 </para>
8216 </listitem>
8218 <listitem>
8219 <para>
8220 Ordinary text is allowed in <function>to_char</function>
8221 templates and will be output literally. You can put a substring
8222 in double quotes to force it to be interpreted as literal text
8223 even if it contains template patterns. For example, in
8224 <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
8225 will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
8226 will not be.
8227 In <function>to_date</function>, <function>to_number</function>,
8228 and <function>to_timestamp</function>, literal text and double-quoted
8229 strings result in skipping the number of characters contained in the
8230 string; for example <literal>"XX"</literal> skips two input characters
8231 (whether or not they are <literal>XX</literal>).
8232 </para>
8233 <tip>
8234 <para>
8235 Prior to <productname>PostgreSQL</productname> 12, it was possible to
8236 skip arbitrary text in the input string using non-letter or non-digit
8237 characters. For example,
8238 <literal>to_timestamp('2000y6m1d', 'yyyy-MM-DD')</literal> used to
8239 work. Now you can only use letter characters for this purpose. For example,
8240 <literal>to_timestamp('2000y6m1d', 'yyyytMMtDDt')</literal> and
8241 <literal>to_timestamp('2000y6m1d', 'yyyy"y"MM"m"DD"d"')</literal>
8242 skip <literal>y</literal>, <literal>m</literal>, and
8243 <literal>d</literal>.
8244 </para>
8245 </tip>
8246 </listitem>
8248 <listitem>
8249 <para>
8250 If you want to have a double quote in the output you must
8251 precede it with a backslash, for example <literal>'\"YYYY
8252 Month\"'</literal>. <!-- "" font-lock sanity :-) -->
8253 Backslashes are not otherwise special outside of double-quoted
8254 strings. Within a double-quoted string, a backslash causes the
8255 next character to be taken literally, whatever it is (but this
8256 has no special effect unless the next character is a double quote
8257 or another backslash).
8258 </para>
8259 </listitem>
8261 <listitem>
8262 <para>
8263 In <function>to_timestamp</function> and <function>to_date</function>,
8264 if the year format specification is less than four digits, e.g.,
8265 <literal>YYY</literal>, and the supplied year is less than four digits,
8266 the year will be adjusted to be nearest to the year 2020, e.g.,
8267 <literal>95</literal> becomes 1995.
8268 </para>
8269 </listitem>
8271 <listitem>
8272 <para>
8273 In <function>to_timestamp</function> and <function>to_date</function>,
8274 negative years are treated as signifying BC. If you write both a
8275 negative year and an explicit <literal>BC</literal> field, you get AD
8276 again. An input of year zero is treated as 1 BC.
8277 </para>
8278 </listitem>
8280 <listitem>
8281 <para>
8282 In <function>to_timestamp</function> and <function>to_date</function>,
8283 the <literal>YYYY</literal> conversion has a restriction when
8284 processing years with more than 4 digits. You must
8285 use some non-digit character or template after <literal>YYYY</literal>,
8286 otherwise the year is always interpreted as 4 digits. For example
8287 (with the year 20000):
8288 <literal>to_date('200001130', 'YYYYMMDD')</literal> will be
8289 interpreted as a 4-digit year; instead use a non-digit
8290 separator after the year, like
8291 <literal>to_date('20000-1130', 'YYYY-MMDD')</literal> or
8292 <literal>to_date('20000Nov30', 'YYYYMonDD')</literal>.
8293 </para>
8294 </listitem>
8296 <listitem>
8297 <para>
8298 In <function>to_timestamp</function> and <function>to_date</function>,
8299 the <literal>CC</literal> (century) field is accepted but ignored
8300 if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
8301 <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
8302 <literal>YY</literal> or <literal>Y</literal> then the result is
8303 computed as that year in the specified century. If the century is
8304 specified but the year is not, the first year of the century
8305 is assumed.
8306 </para>
8307 </listitem>
8309 <listitem>
8310 <para>
8311 In <function>to_timestamp</function> and <function>to_date</function>,
8312 weekday names or numbers (<literal>DAY</literal>, <literal>D</literal>,
8313 and related field types) are accepted but are ignored for purposes of
8314 computing the result. The same is true for quarter
8315 (<literal>Q</literal>) fields.
8316 </para>
8317 </listitem>
8319 <listitem>
8320 <para>
8321 In <function>to_timestamp</function> and <function>to_date</function>,
8322 an ISO 8601 week-numbering date (as distinct from a Gregorian date)
8323 can be specified in one of two ways:
8324 <itemizedlist>
8325 <listitem>
8326 <para>
8327 Year, week number, and weekday: for
8328 example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal>
8329 returns the date <literal>2006-10-19</literal>.
8330 If you omit the weekday it is assumed to be 1 (Monday).
8331 </para>
8332 </listitem>
8333 <listitem>
8334 <para>
8335 Year and day of year: for example <literal>to_date('2006-291',
8336 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
8337 </para>
8338 </listitem>
8339 </itemizedlist>
8340 </para>
8341 <para>
8342 Attempting to enter a date using a mixture of ISO 8601 week-numbering
8343 fields and Gregorian date fields is nonsensical, and will cause an
8344 error. In the context of an ISO 8601 week-numbering year, the
8345 concept of a <quote>month</quote> or <quote>day of month</quote> has no
8346 meaning. In the context of a Gregorian year, the ISO week has no
8347 meaning.
8348 </para>
8349 <caution>
8350 <para>
8351 While <function>to_date</function> will reject a mixture of
8352 Gregorian and ISO week-numbering date
8353 fields, <function>to_char</function> will not, since output format
8354 specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</literal> can be
8355 useful. But avoid writing something like <literal>IYYY-MM-DD</literal>;
8356 that would yield surprising results near the start of the year.
8357 (See <xref linkend="functions-datetime-extract"/> for more
8358 information.)
8359 </para>
8360 </caution>
8361 </listitem>
8363 <listitem>
8364 <para>
8365 In <function>to_timestamp</function>, millisecond
8366 (<literal>MS</literal>) or microsecond (<literal>US</literal>)
8367 fields are used as the
8368 seconds digits after the decimal point. For example
8369 <literal>to_timestamp('12.3', 'SS.MS')</literal> is not 3 milliseconds,
8370 but 300, because the conversion treats it as 12 + 0.3 seconds.
8371 So, for the format <literal>SS.MS</literal>, the input values
8372 <literal>12.3</literal>, <literal>12.30</literal>,
8373 and <literal>12.300</literal> specify the
8374 same number of milliseconds. To get three milliseconds, one must write
8375 <literal>12.003</literal>, which the conversion treats as
8376 12 + 0.003 = 12.003 seconds.
8377 </para>
8379 <para>
8380 Here is a more
8381 complex example:
8382 <literal>to_timestamp('15:12:02.020.001230', 'HH24:MI:SS.MS.US')</literal>
8383 is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
8384 1230 microseconds = 2.021230 seconds.
8385 </para>
8386 </listitem>
8388 <listitem>
8389 <para>
8390 <function>to_char(..., 'ID')</function>'s day of the week numbering
8391 matches the <function>extract(isodow from ...)</function> function, but
8392 <function>to_char(..., 'D')</function>'s does not match
8393 <function>extract(dow from ...)</function>'s day numbering.
8394 </para>
8395 </listitem>
8397 <listitem>
8398 <para>
8399 <function>to_char(interval)</function> formats <literal>HH</literal> and
8400 <literal>HH12</literal> as shown on a 12-hour clock, for example zero hours
8401 and 36 hours both output as <literal>12</literal>, while <literal>HH24</literal>
8402 outputs the full hour value, which can exceed 23 in
8403 an <type>interval</type> value.
8404 </para>
8405 </listitem>
8407 </itemizedlist>
8408 </para>
8410 <para>
8411 <xref linkend="functions-formatting-numeric-table"/> shows the
8412 template patterns available for formatting numeric values.
8413 </para>
8415 <table id="functions-formatting-numeric-table">
8416 <title>Template Patterns for Numeric Formatting</title>
8417 <tgroup cols="2">
8418 <thead>
8419 <row>
8420 <entry>Pattern</entry>
8421 <entry>Description</entry>
8422 </row>
8423 </thead>
8424 <tbody>
8425 <row>
8426 <entry><literal>9</literal></entry>
8427 <entry>digit position (can be dropped if insignificant)</entry>
8428 </row>
8429 <row>
8430 <entry><literal>0</literal></entry>
8431 <entry>digit position (will not be dropped, even if insignificant)</entry>
8432 </row>
8433 <row>
8434 <entry><literal>.</literal> (period)</entry>
8435 <entry>decimal point</entry>
8436 </row>
8437 <row>
8438 <entry><literal>,</literal> (comma)</entry>
8439 <entry>group (thousands) separator</entry>
8440 </row>
8441 <row>
8442 <entry><literal>PR</literal></entry>
8443 <entry>negative value in angle brackets</entry>
8444 </row>
8445 <row>
8446 <entry><literal>S</literal></entry>
8447 <entry>sign anchored to number (uses locale)</entry>
8448 </row>
8449 <row>
8450 <entry><literal>L</literal></entry>
8451 <entry>currency symbol (uses locale)</entry>
8452 </row>
8453 <row>
8454 <entry><literal>D</literal></entry>
8455 <entry>decimal point (uses locale)</entry>
8456 </row>
8457 <row>
8458 <entry><literal>G</literal></entry>
8459 <entry>group separator (uses locale)</entry>
8460 </row>
8461 <row>
8462 <entry><literal>MI</literal></entry>
8463 <entry>minus sign in specified position (if number &lt; 0)</entry>
8464 </row>
8465 <row>
8466 <entry><literal>PL</literal></entry>
8467 <entry>plus sign in specified position (if number &gt; 0)</entry>
8468 </row>
8469 <row>
8470 <entry><literal>SG</literal></entry>
8471 <entry>plus/minus sign in specified position</entry>
8472 </row>
8473 <row>
8474 <entry><literal>RN</literal></entry>
8475 <entry>Roman numeral (input between 1 and 3999)</entry>
8476 </row>
8477 <row>
8478 <entry><literal>TH</literal> or <literal>th</literal></entry>
8479 <entry>ordinal number suffix</entry>
8480 </row>
8481 <row>
8482 <entry><literal>V</literal></entry>
8483 <entry>shift specified number of digits (see notes)</entry>
8484 </row>
8485 <row>
8486 <entry><literal>EEEE</literal></entry>
8487 <entry>exponent for scientific notation</entry>
8488 </row>
8489 </tbody>
8490 </tgroup>
8491 </table>
8493 <para>
8494 Usage notes for numeric formatting:
8496 <itemizedlist>
8497 <listitem>
8498 <para>
8499 <literal>0</literal> specifies a digit position that will always be printed,
8500 even if it contains a leading/trailing zero. <literal>9</literal> also
8501 specifies a digit position, but if it is a leading zero then it will
8502 be replaced by a space, while if it is a trailing zero and fill mode
8503 is specified then it will be deleted. (For <function>to_number()</function>,
8504 these two pattern characters are equivalent.)
8505 </para>
8506 </listitem>
8508 <listitem>
8509 <para>
8510 If the format provides fewer fractional digits than the number being
8511 formatted, <function>to_char()</function> will round the number to
8512 the specified number of fractional digits.
8513 </para>
8514 </listitem>
8516 <listitem>
8517 <para>
8518 The pattern characters <literal>S</literal>, <literal>L</literal>, <literal>D</literal>,
8519 and <literal>G</literal> represent the sign, currency symbol, decimal point,
8520 and thousands separator characters defined by the current locale
8521 (see <xref linkend="guc-lc-monetary"/>
8522 and <xref linkend="guc-lc-numeric"/>). The pattern characters period
8523 and comma represent those exact characters, with the meanings of
8524 decimal point and thousands separator, regardless of locale.
8525 </para>
8526 </listitem>
8528 <listitem>
8529 <para>
8530 If no explicit provision is made for a sign
8531 in <function>to_char()</function>'s pattern, one column will be reserved for
8532 the sign, and it will be anchored to (appear just left of) the
8533 number. If <literal>S</literal> appears just left of some <literal>9</literal>'s,
8534 it will likewise be anchored to the number.
8535 </para>
8536 </listitem>
8538 <listitem>
8539 <para>
8540 A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
8541 <literal>MI</literal> is not anchored to
8542 the number; for example,
8543 <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
8544 but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
8545 (The Oracle implementation does not allow the use of
8546 <literal>MI</literal> before <literal>9</literal>, but rather
8547 requires that <literal>9</literal> precede
8548 <literal>MI</literal>.)
8549 </para>
8550 </listitem>
8552 <listitem>
8553 <para>
8554 <literal>TH</literal> does not convert values less than zero
8555 and does not convert fractional numbers.
8556 </para>
8557 </listitem>
8559 <listitem>
8560 <para>
8561 <literal>PL</literal>, <literal>SG</literal>, and
8562 <literal>TH</literal> are <productname>PostgreSQL</productname>
8563 extensions.
8564 </para>
8565 </listitem>
8567 <listitem>
8568 <para>
8569 In <function>to_number</function>, if non-data template patterns such
8570 as <literal>L</literal> or <literal>TH</literal> are used, the
8571 corresponding number of input characters are skipped, whether or not
8572 they match the template pattern, unless they are data characters
8573 (that is, digits, sign, decimal point, or comma). For
8574 example, <literal>TH</literal> would skip two non-data characters.
8575 </para>
8576 </listitem>
8578 <listitem>
8579 <para>
8580 <literal>V</literal> with <function>to_char</function>
8581 multiplies the input values by
8582 <literal>10^<replaceable>n</replaceable></literal>, where
8583 <replaceable>n</replaceable> is the number of digits following
8584 <literal>V</literal>. <literal>V</literal> with
8585 <function>to_number</function> divides in a similar manner.
8586 <function>to_char</function> and <function>to_number</function>
8587 do not support the use of
8588 <literal>V</literal> combined with a decimal point
8589 (e.g., <literal>99.9V99</literal> is not allowed).
8590 </para>
8591 </listitem>
8593 <listitem>
8594 <para>
8595 <literal>EEEE</literal> (scientific notation) cannot be used in
8596 combination with any of the other formatting patterns or
8597 modifiers other than digit and decimal point patterns, and must be at the end of the format string
8598 (e.g., <literal>9.99EEEE</literal> is a valid pattern).
8599 </para>
8600 </listitem>
8601 </itemizedlist>
8602 </para>
8604 <para>
8605 Certain modifiers can be applied to any template pattern to alter its
8606 behavior. For example, <literal>FM99.99</literal>
8607 is the <literal>99.99</literal> pattern with the
8608 <literal>FM</literal> modifier.
8609 <xref linkend="functions-formatting-numericmod-table"/> shows the
8610 modifier patterns for numeric formatting.
8611 </para>
8613 <table id="functions-formatting-numericmod-table">
8614 <title>Template Pattern Modifiers for Numeric Formatting</title>
8615 <tgroup cols="3">
8616 <thead>
8617 <row>
8618 <entry>Modifier</entry>
8619 <entry>Description</entry>
8620 <entry>Example</entry>
8621 </row>
8622 </thead>
8623 <tbody>
8624 <row>
8625 <entry><literal>FM</literal> prefix</entry>
8626 <entry>fill mode (suppress trailing zeroes and padding blanks)</entry>
8627 <entry><literal>FM99.99</literal></entry>
8628 </row>
8629 <row>
8630 <entry><literal>TH</literal> suffix</entry>
8631 <entry>upper case ordinal number suffix</entry>
8632 <entry><literal>999TH</literal></entry>
8633 </row>
8634 <row>
8635 <entry><literal>th</literal> suffix</entry>
8636 <entry>lower case ordinal number suffix</entry>
8637 <entry><literal>999th</literal></entry>
8638 </row>
8639 </tbody>
8640 </tgroup>
8641 </table>
8643 <para>
8644 <xref linkend="functions-formatting-examples-table"/> shows some
8645 examples of the use of the <function>to_char</function> function.
8646 </para>
8648 <table id="functions-formatting-examples-table">
8649 <title><function>to_char</function> Examples</title>
8650 <tgroup cols="2">
8651 <thead>
8652 <row>
8653 <entry>Expression</entry>
8654 <entry>Result</entry>
8655 </row>
8656 </thead>
8657 <tbody>
8658 <row>
8659 <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8660 <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
8661 </row>
8662 <row>
8663 <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8664 <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
8665 </row>
8666 <row>
8667 <entry><literal>to_char(-0.1, '99.99')</literal></entry>
8668 <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
8669 </row>
8670 <row>
8671 <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
8672 <entry><literal>'-.1'</literal></entry>
8673 </row>
8674 <row>
8675 <entry><literal>to_char(-0.1, 'FM90.99')</literal></entry>
8676 <entry><literal>'-0.1'</literal></entry>
8677 </row>
8678 <row>
8679 <entry><literal>to_char(0.1, '0.9')</literal></entry>
8680 <entry><literal>'&nbsp;0.1'</literal></entry>
8681 </row>
8682 <row>
8683 <entry><literal>to_char(12, '9990999.9')</literal></entry>
8684 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
8685 </row>
8686 <row>
8687 <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
8688 <entry><literal>'0012.'</literal></entry>
8689 </row>
8690 <row>
8691 <entry><literal>to_char(485, '999')</literal></entry>
8692 <entry><literal>'&nbsp;485'</literal></entry>
8693 </row>
8694 <row>
8695 <entry><literal>to_char(-485, '999')</literal></entry>
8696 <entry><literal>'-485'</literal></entry>
8697 </row>
8698 <row>
8699 <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
8700 <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
8701 </row>
8702 <row>
8703 <entry><literal>to_char(1485, '9,999')</literal></entry>
8704 <entry><literal>'&nbsp;1,485'</literal></entry>
8705 </row>
8706 <row>
8707 <entry><literal>to_char(1485, '9G999')</literal></entry>
8708 <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
8709 </row>
8710 <row>
8711 <entry><literal>to_char(148.5, '999.999')</literal></entry>
8712 <entry><literal>'&nbsp;148.500'</literal></entry>
8713 </row>
8714 <row>
8715 <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
8716 <entry><literal>'148.5'</literal></entry>
8717 </row>
8718 <row>
8719 <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
8720 <entry><literal>'148.500'</literal></entry>
8721 </row>
8722 <row>
8723 <entry><literal>to_char(148.5, '999D999')</literal></entry>
8724 <entry><literal>'&nbsp;148,500'</literal></entry>
8725 </row>
8726 <row>
8727 <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
8728 <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
8729 </row>
8730 <row>
8731 <entry><literal>to_char(-485, '999S')</literal></entry>
8732 <entry><literal>'485-'</literal></entry>
8733 </row>
8734 <row>
8735 <entry><literal>to_char(-485, '999MI')</literal></entry>
8736 <entry><literal>'485-'</literal></entry>
8737 </row>
8738 <row>
8739 <entry><literal>to_char(485, '999MI')</literal></entry>
8740 <entry><literal>'485&nbsp;'</literal></entry>
8741 </row>
8742 <row>
8743 <entry><literal>to_char(485, 'FM999MI')</literal></entry>
8744 <entry><literal>'485'</literal></entry>
8745 </row>
8746 <row>
8747 <entry><literal>to_char(485, 'PL999')</literal></entry>
8748 <entry><literal>'+485'</literal></entry>
8749 </row>
8750 <row>
8751 <entry><literal>to_char(485, 'SG999')</literal></entry>
8752 <entry><literal>'+485'</literal></entry>
8753 </row>
8754 <row>
8755 <entry><literal>to_char(-485, 'SG999')</literal></entry>
8756 <entry><literal>'-485'</literal></entry>
8757 </row>
8758 <row>
8759 <entry><literal>to_char(-485, '9SG99')</literal></entry>
8760 <entry><literal>'4-85'</literal></entry>
8761 </row>
8762 <row>
8763 <entry><literal>to_char(-485, '999PR')</literal></entry>
8764 <entry><literal>'&lt;485&gt;'</literal></entry>
8765 </row>
8766 <row>
8767 <entry><literal>to_char(485, 'L999')</literal></entry>
8768 <entry><literal>'DM&nbsp;485'</literal></entry>
8769 </row>
8770 <row>
8771 <entry><literal>to_char(485, 'RN')</literal></entry>
8772 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
8773 </row>
8774 <row>
8775 <entry><literal>to_char(485, 'FMRN')</literal></entry>
8776 <entry><literal>'CDLXXXV'</literal></entry>
8777 </row>
8778 <row>
8779 <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
8780 <entry><literal>'V'</literal></entry>
8781 </row>
8782 <row>
8783 <entry><literal>to_char(482, '999th')</literal></entry>
8784 <entry><literal>'&nbsp;482nd'</literal></entry>
8785 </row>
8786 <row>
8787 <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
8788 <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
8789 </row>
8790 <row>
8791 <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
8792 <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
8793 </row>
8794 <row>
8795 <entry><literal>to_char(12, '99V999')</literal></entry>
8796 <entry><literal>'&nbsp;12000'</literal></entry>
8797 </row>
8798 <row>
8799 <entry><literal>to_char(12.4, '99V999')</literal></entry>
8800 <entry><literal>'&nbsp;12400'</literal></entry>
8801 </row>
8802 <row>
8803 <entry><literal>to_char(12.45, '99V9')</literal></entry>
8804 <entry><literal>'&nbsp;125'</literal></entry>
8805 </row>
8806 <row>
8807 <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
8808 <entry><literal>' 4.86e-04'</literal></entry>
8809 </row>
8810 </tbody>
8811 </tgroup>
8812 </table>
8814 </sect1>
8817 <sect1 id="functions-datetime">
8818 <title>Date/Time Functions and Operators</title>
8820 <para>
8821 <xref linkend="functions-datetime-table"/> shows the available
8822 functions for date/time value processing, with details appearing in
8823 the following subsections. <xref
8824 linkend="operators-datetime-table"/> illustrates the behaviors of
8825 the basic arithmetic operators (<literal>+</literal>,
8826 <literal>*</literal>, etc.). For formatting functions, refer to
8827 <xref linkend="functions-formatting"/>. You should be familiar with
8828 the background information on date/time data types from <xref
8829 linkend="datatype-datetime"/>.
8830 </para>
8832 <para>
8833 In addition, the usual comparison operators shown in
8834 <xref linkend="functions-comparison-op-table"/> are available for the
8835 date/time types. Dates and timestamps (with or without time zone) are
8836 all comparable, while times (with or without time zone) and intervals
8837 can only be compared to other values of the same data type. When
8838 comparing a timestamp without time zone to a timestamp with time zone,
8839 the former value is assumed to be given in the time zone specified by
8840 the <xref linkend="guc-timezone"/> configuration parameter, and is
8841 rotated to UTC for comparison to the latter value (which is already
8842 in UTC internally). Similarly, a date value is assumed to represent
8843 midnight in the <varname>TimeZone</varname> zone when comparing it
8844 to a timestamp.
8845 </para>
8847 <para>
8848 All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
8849 inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
8850 with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
8851 For brevity, these variants are not shown separately. Also, the
8852 <literal>+</literal> and <literal>*</literal> operators come in commutative pairs (for
8853 example both <type>date</type> <literal>+</literal> <type>integer</type>
8854 and <type>integer</type> <literal>+</literal> <type>date</type>); we show
8855 only one of each such pair.
8856 </para>
8858 <table id="operators-datetime-table">
8859 <title>Date/Time Operators</title>
8861 <tgroup cols="1">
8862 <thead>
8863 <row>
8864 <entry role="func_table_entry"><para role="func_signature">
8865 Operator
8866 </para>
8867 <para>
8868 Description
8869 </para>
8870 <para>
8871 Example(s)
8872 </para></entry>
8873 </row>
8874 </thead>
8876 <tbody>
8877 <row>
8878 <entry role="func_table_entry"><para role="func_signature">
8879 <type>date</type> <literal>+</literal> <type>integer</type>
8880 <returnvalue>date</returnvalue>
8881 </para>
8882 <para>
8883 Add a number of days to a date
8884 </para>
8885 <para>
8886 <literal>date '2001-09-28' + 7</literal>
8887 <returnvalue>2001-10-05</returnvalue>
8888 </para></entry>
8889 </row>
8891 <row>
8892 <entry role="func_table_entry"><para role="func_signature">
8893 <type>date</type> <literal>+</literal> <type>interval</type>
8894 <returnvalue>timestamp</returnvalue>
8895 </para>
8896 <para>
8897 Add an interval to a date
8898 </para>
8899 <para>
8900 <literal>date '2001-09-28' + interval '1 hour'</literal>
8901 <returnvalue>2001-09-28 01:00:00</returnvalue>
8902 </para></entry>
8903 </row>
8905 <row>
8906 <entry role="func_table_entry"><para role="func_signature">
8907 <type>date</type> <literal>+</literal> <type>time</type>
8908 <returnvalue>timestamp</returnvalue>
8909 </para>
8910 <para>
8911 Add a time-of-day to a date
8912 </para>
8913 <para>
8914 <literal>date '2001-09-28' + time '03:00'</literal>
8915 <returnvalue>2001-09-28 03:00:00</returnvalue>
8916 </para></entry>
8917 </row>
8919 <row>
8920 <entry role="func_table_entry"><para role="func_signature">
8921 <type>interval</type> <literal>+</literal> <type>interval</type>
8922 <returnvalue>interval</returnvalue>
8923 </para>
8924 <para>
8925 Add intervals
8926 </para>
8927 <para>
8928 <literal>interval '1 day' + interval '1 hour'</literal>
8929 <returnvalue>1 day 01:00:00</returnvalue>
8930 </para></entry>
8931 </row>
8933 <row>
8934 <entry role="func_table_entry"><para role="func_signature">
8935 <type>timestamp</type> <literal>+</literal> <type>interval</type>
8936 <returnvalue>timestamp</returnvalue>
8937 </para>
8938 <para>
8939 Add an interval to a timestamp
8940 </para>
8941 <para>
8942 <literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal>
8943 <returnvalue>2001-09-29 00:00:00</returnvalue>
8944 </para></entry>
8945 </row>
8947 <row>
8948 <entry role="func_table_entry"><para role="func_signature">
8949 <type>time</type> <literal>+</literal> <type>interval</type>
8950 <returnvalue>time</returnvalue>
8951 </para>
8952 <para>
8953 Add an interval to a time
8954 </para>
8955 <para>
8956 <literal>time '01:00' + interval '3 hours'</literal>
8957 <returnvalue>04:00:00</returnvalue>
8958 </para></entry>
8959 </row>
8961 <row>
8962 <entry role="func_table_entry"><para role="func_signature">
8963 <literal>-</literal> <type>interval</type>
8964 <returnvalue>interval</returnvalue>
8965 </para>
8966 <para>
8967 Negate an interval
8968 </para>
8969 <para>
8970 <literal>- interval '23 hours'</literal>
8971 <returnvalue>-23:00:00</returnvalue>
8972 </para></entry>
8973 </row>
8975 <row>
8976 <entry role="func_table_entry"><para role="func_signature">
8977 <type>date</type> <literal>-</literal> <type>date</type>
8978 <returnvalue>integer</returnvalue>
8979 </para>
8980 <para>
8981 Subtract dates, producing the number of days elapsed
8982 </para>
8983 <para>
8984 <literal>date '2001-10-01' - date '2001-09-28'</literal>
8985 <returnvalue>3</returnvalue>
8986 </para></entry>
8987 </row>
8989 <row>
8990 <entry role="func_table_entry"><para role="func_signature">
8991 <type>date</type> <literal>-</literal> <type>integer</type>
8992 <returnvalue>date</returnvalue>
8993 </para>
8994 <para>
8995 Subtract a number of days from a date
8996 </para>
8997 <para>
8998 <literal>date '2001-10-01' - 7</literal>
8999 <returnvalue>2001-09-24</returnvalue>
9000 </para></entry>
9001 </row>
9003 <row>
9004 <entry role="func_table_entry"><para role="func_signature">
9005 <type>date</type> <literal>-</literal> <type>interval</type>
9006 <returnvalue>timestamp</returnvalue>
9007 </para>
9008 <para>
9009 Subtract an interval from a date
9010 </para>
9011 <para>
9012 <literal>date '2001-09-28' - interval '1 hour'</literal>
9013 <returnvalue>2001-09-27 23:00:00</returnvalue>
9014 </para></entry>
9015 </row>
9017 <row>
9018 <entry role="func_table_entry"><para role="func_signature">
9019 <type>time</type> <literal>-</literal> <type>time</type>
9020 <returnvalue>interval</returnvalue>
9021 </para>
9022 <para>
9023 Subtract times
9024 </para>
9025 <para>
9026 <literal>time '05:00' - time '03:00'</literal>
9027 <returnvalue>02:00:00</returnvalue>
9028 </para></entry>
9029 </row>
9031 <row>
9032 <entry role="func_table_entry"><para role="func_signature">
9033 <type>time</type> <literal>-</literal> <type>interval</type>
9034 <returnvalue>time</returnvalue>
9035 </para>
9036 <para>
9037 Subtract an interval from a time
9038 </para>
9039 <para>
9040 <literal>time '05:00' - interval '2 hours'</literal>
9041 <returnvalue>03:00:00</returnvalue>
9042 </para></entry>
9043 </row>
9045 <row>
9046 <entry role="func_table_entry"><para role="func_signature">
9047 <type>timestamp</type> <literal>-</literal> <type>interval</type>
9048 <returnvalue>timestamp</returnvalue>
9049 </para>
9050 <para>
9051 Subtract an interval from a timestamp
9052 </para>
9053 <para>
9054 <literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal>
9055 <returnvalue>2001-09-28 00:00:00</returnvalue>
9056 </para></entry>
9057 </row>
9059 <row>
9060 <entry role="func_table_entry"><para role="func_signature">
9061 <type>interval</type> <literal>-</literal> <type>interval</type>
9062 <returnvalue>interval</returnvalue>
9063 </para>
9064 <para>
9065 Subtract intervals
9066 </para>
9067 <para>
9068 <literal>interval '1 day' - interval '1 hour'</literal>
9069 <returnvalue>1 day -01:00:00</returnvalue>
9070 </para></entry>
9071 </row>
9073 <row>
9074 <entry role="func_table_entry"><para role="func_signature">
9075 <type>timestamp</type> <literal>-</literal> <type>timestamp</type>
9076 <returnvalue>interval</returnvalue>
9077 </para>
9078 <para>
9079 Subtract timestamps (converting 24-hour intervals into days,
9080 similarly to <link
9081 linkend="function-justify-hours"><function>justify_hours()</function></link>)
9082 </para>
9083 <para>
9084 <literal>timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00'</literal>
9085 <returnvalue>63 days 15:00:00</returnvalue>
9086 </para></entry>
9087 </row>
9089 <row>
9090 <entry role="func_table_entry"><para role="func_signature">
9091 <type>interval</type> <literal>*</literal> <type>double precision</type>
9092 <returnvalue>interval</returnvalue>
9093 </para>
9094 <para>
9095 Multiply an interval by a scalar
9096 </para>
9097 <para>
9098 <literal>interval '1 second' * 900</literal>
9099 <returnvalue>00:15:00</returnvalue>
9100 </para>
9101 <para>
9102 <literal>interval '1 day' * 21</literal>
9103 <returnvalue>21 days</returnvalue>
9104 </para>
9105 <para>
9106 <literal>interval '1 hour' * 3.5</literal>
9107 <returnvalue>03:30:00</returnvalue>
9108 </para></entry>
9109 </row>
9111 <row>
9112 <entry role="func_table_entry"><para role="func_signature">
9113 <type>interval</type> <literal>/</literal> <type>double precision</type>
9114 <returnvalue>interval</returnvalue>
9115 </para>
9116 <para>
9117 Divide an interval by a scalar
9118 </para>
9119 <para>
9120 <literal>interval '1 hour' / 1.5</literal>
9121 <returnvalue>00:40:00</returnvalue>
9122 </para></entry>
9123 </row>
9124 </tbody>
9125 </tgroup>
9126 </table>
9128 <table id="functions-datetime-table">
9129 <title>Date/Time Functions</title>
9130 <tgroup cols="1">
9131 <thead>
9132 <row>
9133 <entry role="func_table_entry"><para role="func_signature">
9134 Function
9135 </para>
9136 <para>
9137 Description
9138 </para>
9139 <para>
9140 Example(s)
9141 </para></entry>
9142 </row>
9143 </thead>
9145 <tbody>
9146 <row>
9147 <entry role="func_table_entry"><para role="func_signature">
9148 <indexterm>
9149 <primary>age</primary>
9150 </indexterm>
9151 <function>age</function> ( <type>timestamp</type>, <type>timestamp</type> )
9152 <returnvalue>interval</returnvalue>
9153 </para>
9154 <para>
9155 Subtract arguments, producing a <quote>symbolic</quote> result that
9156 uses years and months, rather than just days
9157 </para>
9158 <para>
9159 <literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal>
9160 <returnvalue>43 years 9 mons 27 days</returnvalue>
9161 </para></entry>
9162 </row>
9164 <row>
9165 <entry role="func_table_entry"><para role="func_signature">
9166 <function>age</function> ( <type>timestamp</type> )
9167 <returnvalue>interval</returnvalue>
9168 </para>
9169 <para>
9170 Subtract argument from <function>current_date</function> (at midnight)
9171 </para>
9172 <para>
9173 <literal>age(timestamp '1957-06-13')</literal>
9174 <returnvalue>62 years 6 mons 10 days</returnvalue>
9175 </para></entry>
9176 </row>
9178 <row>
9179 <entry role="func_table_entry"><para role="func_signature">
9180 <indexterm>
9181 <primary>clock_timestamp</primary>
9182 </indexterm>
9183 <function>clock_timestamp</function> ( )
9184 <returnvalue>timestamp with time zone</returnvalue>
9185 </para>
9186 <para>
9187 Current date and time (changes during statement execution);
9188 see <xref linkend="functions-datetime-current"/>
9189 </para>
9190 <para>
9191 <literal>clock_timestamp()</literal>
9192 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9193 </para></entry>
9194 </row>
9196 <row>
9197 <entry role="func_table_entry"><para role="func_signature">
9198 <indexterm>
9199 <primary>current_date</primary>
9200 </indexterm>
9201 <function>current_date</function>
9202 <returnvalue>date</returnvalue>
9203 </para>
9204 <para>
9205 Current date; see <xref linkend="functions-datetime-current"/>
9206 </para>
9207 <para>
9208 <literal>current_date</literal>
9209 <returnvalue>2019-12-23</returnvalue>
9210 </para></entry>
9211 </row>
9213 <row>
9214 <entry role="func_table_entry"><para role="func_signature">
9215 <indexterm>
9216 <primary>current_time</primary>
9217 </indexterm>
9218 <function>current_time</function>
9219 <returnvalue>time with time zone</returnvalue>
9220 </para>
9221 <para>
9222 Current time of day; see <xref linkend="functions-datetime-current"/>
9223 </para>
9224 <para>
9225 <literal>current_time</literal>
9226 <returnvalue>14:39:53.662522-05</returnvalue>
9227 </para></entry>
9228 </row>
9230 <row>
9231 <entry role="func_table_entry"><para role="func_signature">
9232 <function>current_time</function> ( <type>integer</type> )
9233 <returnvalue>time with time zone</returnvalue>
9234 </para>
9235 <para>
9236 Current time of day, with limited precision;
9237 see <xref linkend="functions-datetime-current"/>
9238 </para>
9239 <para>
9240 <literal>current_time(2)</literal>
9241 <returnvalue>14:39:53.66-05</returnvalue>
9242 </para></entry>
9243 </row>
9245 <row>
9246 <entry role="func_table_entry"><para role="func_signature">
9247 <indexterm>
9248 <primary>current_timestamp</primary>
9249 </indexterm>
9250 <function>current_timestamp</function>
9251 <returnvalue>timestamp with time zone</returnvalue>
9252 </para>
9253 <para>
9254 Current date and time (start of current transaction);
9255 see <xref linkend="functions-datetime-current"/>
9256 </para>
9257 <para>
9258 <literal>current_timestamp</literal>
9259 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9260 </para></entry>
9261 </row>
9263 <row>
9264 <entry role="func_table_entry"><para role="func_signature">
9265 <function>current_timestamp</function> ( <type>integer</type> )
9266 <returnvalue>timestamp with time zone</returnvalue>
9267 </para>
9268 <para>
9269 Current date and time (start of current transaction), with limited precision;
9270 see <xref linkend="functions-datetime-current"/>
9271 </para>
9272 <para>
9273 <literal>current_timestamp(0)</literal>
9274 <returnvalue>2019-12-23 14:39:53-05</returnvalue>
9275 </para></entry>
9276 </row>
9278 <row>
9279 <entry role="func_table_entry"><para role="func_signature">
9280 <indexterm>
9281 <primary>date_add</primary>
9282 </indexterm>
9283 <function>date_add</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
9284 <returnvalue>timestamp with time zone</returnvalue>
9285 </para>
9286 <para>
9287 Add an <type>interval</type> to a <type>timestamp with time
9288 zone</type>, computing times of day and daylight-savings adjustments
9289 according to the time zone named by the third argument, or the
9290 current <xref linkend="guc-timezone"/> setting if that is omitted.
9291 The form with two arguments is equivalent to the <type>timestamp with
9292 time zone</type> <literal>+</literal> <type>interval</type> operator.
9293 </para>
9294 <para>
9295 <literal>date_add('2021-10-31 00:00:00+02'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
9296 <returnvalue>2021-10-31 23:00:00+00</returnvalue>
9297 </para></entry>
9298 </row>
9300 <row>
9301 <entry role="func_table_entry"><para role="func_signature">
9302 <function>date_bin</function> ( <type>interval</type>, <type>timestamp</type>, <type>timestamp</type> )
9303 <returnvalue>timestamp</returnvalue>
9304 </para>
9305 <para>
9306 Bin input into specified interval aligned with specified origin; see <xref linkend="functions-datetime-bin"/>
9307 </para>
9308 <para>
9309 <literal>date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00')</literal>
9310 <returnvalue>2001-02-16 20:35:00</returnvalue>
9311 </para></entry>
9312 </row>
9314 <row>
9315 <entry role="func_table_entry"><para role="func_signature">
9316 <indexterm>
9317 <primary>date_part</primary>
9318 </indexterm>
9319 <function>date_part</function> ( <type>text</type>, <type>timestamp</type> )
9320 <returnvalue>double precision</returnvalue>
9321 </para>
9322 <para>
9323 Get timestamp subfield (equivalent to <function>extract</function>);
9324 see <xref linkend="functions-datetime-extract"/>
9325 </para>
9326 <para>
9327 <literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal>
9328 <returnvalue>20</returnvalue>
9329 </para></entry>
9330 </row>
9332 <row>
9333 <entry role="func_table_entry"><para role="func_signature">
9334 <function>date_part</function> ( <type>text</type>, <type>interval</type> )
9335 <returnvalue>double precision</returnvalue>
9336 </para>
9337 <para>
9338 Get interval subfield (equivalent to <function>extract</function>);
9339 see <xref linkend="functions-datetime-extract"/>
9340 </para>
9341 <para>
9342 <literal>date_part('month', interval '2 years 3 months')</literal>
9343 <returnvalue>3</returnvalue>
9344 </para></entry>
9345 </row>
9347 <row>
9348 <entry role="func_table_entry"><para role="func_signature">
9349 <indexterm>
9350 <primary>date_subtract</primary>
9351 </indexterm>
9352 <function>date_subtract</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
9353 <returnvalue>timestamp with time zone</returnvalue>
9354 </para>
9355 <para>
9356 Subtract an <type>interval</type> from a <type>timestamp with time
9357 zone</type>, computing times of day and daylight-savings adjustments
9358 according to the time zone named by the third argument, or the
9359 current <xref linkend="guc-timezone"/> setting if that is omitted.
9360 The form with two arguments is equivalent to the <type>timestamp with
9361 time zone</type> <literal>-</literal> <type>interval</type> operator.
9362 </para>
9363 <para>
9364 <literal>date_subtract('2021-11-01 00:00:00+01'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
9365 <returnvalue>2021-10-30 22:00:00+00</returnvalue>
9366 </para></entry>
9367 </row>
9369 <row>
9370 <entry role="func_table_entry"><para role="func_signature">
9371 <indexterm>
9372 <primary>date_trunc</primary>
9373 </indexterm>
9374 <function>date_trunc</function> ( <type>text</type>, <type>timestamp</type> )
9375 <returnvalue>timestamp</returnvalue>
9376 </para>
9377 <para>
9378 Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
9379 </para>
9380 <para>
9381 <literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal>
9382 <returnvalue>2001-02-16 20:00:00</returnvalue>
9383 </para></entry>
9384 </row>
9386 <row>
9387 <entry role="func_table_entry"><para role="func_signature">
9388 <function>date_trunc</function> ( <type>text</type>, <type>timestamp with time zone</type>, <type>text</type> )
9389 <returnvalue>timestamp with time zone</returnvalue>
9390 </para>
9391 <para>
9392 Truncate to specified precision in the specified time zone; see
9393 <xref linkend="functions-datetime-trunc"/>
9394 </para>
9395 <para>
9396 <literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal>
9397 <returnvalue>2001-02-16 13:00:00+00</returnvalue>
9398 </para></entry>
9399 </row>
9401 <row>
9402 <entry role="func_table_entry"><para role="func_signature">
9403 <function>date_trunc</function> ( <type>text</type>, <type>interval</type> )
9404 <returnvalue>interval</returnvalue>
9405 </para>
9406 <para>
9407 Truncate to specified precision; see
9408 <xref linkend="functions-datetime-trunc"/>
9409 </para>
9410 <para>
9411 <literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal>
9412 <returnvalue>2 days 03:00:00</returnvalue>
9413 </para></entry>
9414 </row>
9416 <row>
9417 <entry role="func_table_entry"><para role="func_signature">
9418 <indexterm>
9419 <primary>extract</primary>
9420 </indexterm>
9421 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> )
9422 <returnvalue>numeric</returnvalue>
9423 </para>
9424 <para>
9425 Get timestamp subfield; see <xref linkend="functions-datetime-extract"/>
9426 </para>
9427 <para>
9428 <literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal>
9429 <returnvalue>20</returnvalue>
9430 </para></entry>
9431 </row>
9433 <row>
9434 <entry role="func_table_entry"><para role="func_signature">
9435 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> )
9436 <returnvalue>numeric</returnvalue>
9437 </para>
9438 <para>
9439 Get interval subfield; see <xref linkend="functions-datetime-extract"/>
9440 </para>
9441 <para>
9442 <literal>extract(month from interval '2 years 3 months')</literal>
9443 <returnvalue>3</returnvalue>
9444 </para></entry>
9445 </row>
9447 <row>
9448 <entry role="func_table_entry"><para role="func_signature">
9449 <indexterm>
9450 <primary>isfinite</primary>
9451 </indexterm>
9452 <function>isfinite</function> ( <type>date</type> )
9453 <returnvalue>boolean</returnvalue>
9454 </para>
9455 <para>
9456 Test for finite date (not +/-infinity)
9457 </para>
9458 <para>
9459 <literal>isfinite(date '2001-02-16')</literal>
9460 <returnvalue>true</returnvalue>
9461 </para></entry>
9462 </row>
9464 <row>
9465 <entry role="func_table_entry"><para role="func_signature">
9466 <function>isfinite</function> ( <type>timestamp</type> )
9467 <returnvalue>boolean</returnvalue>
9468 </para>
9469 <para>
9470 Test for finite timestamp (not +/-infinity)
9471 </para>
9472 <para>
9473 <literal>isfinite(timestamp 'infinity')</literal>
9474 <returnvalue>false</returnvalue>
9475 </para></entry>
9476 </row>
9478 <row>
9479 <entry role="func_table_entry"><para role="func_signature">
9480 <function>isfinite</function> ( <type>interval</type> )
9481 <returnvalue>boolean</returnvalue>
9482 </para>
9483 <para>
9484 Test for finite interval (currently always true)
9485 </para>
9486 <para>
9487 <literal>isfinite(interval '4 hours')</literal>
9488 <returnvalue>true</returnvalue>
9489 </para></entry>
9490 </row>
9492 <row>
9493 <entry role="func_table_entry"><para role="func_signature">
9494 <indexterm id="function-justify-days">
9495 <primary>justify_days</primary>
9496 </indexterm>
9497 <function>justify_days</function> ( <type>interval</type> )
9498 <returnvalue>interval</returnvalue>
9499 </para>
9500 <para>
9501 Adjust interval, converting 30-day time periods to months
9502 </para>
9503 <para>
9504 <literal>justify_days(interval '1 year 65 days')</literal>
9505 <returnvalue>1 year 2 mons 5 days</returnvalue>
9506 </para></entry>
9507 </row>
9509 <row>
9510 <entry role="func_table_entry"><para role="func_signature">
9511 <indexterm id="function-justify-hours">
9512 <primary>justify_hours</primary>
9513 </indexterm>
9514 <function>justify_hours</function> ( <type>interval</type> )
9515 <returnvalue>interval</returnvalue>
9516 </para>
9517 <para>
9518 Adjust interval, converting 24-hour time periods to days
9519 </para>
9520 <para>
9521 <literal>justify_hours(interval '50 hours 10 minutes')</literal>
9522 <returnvalue>2 days 02:10:00</returnvalue>
9523 </para></entry>
9524 </row>
9526 <row>
9527 <entry role="func_table_entry"><para role="func_signature">
9528 <indexterm>
9529 <primary>justify_interval</primary>
9530 </indexterm>
9531 <function>justify_interval</function> ( <type>interval</type> )
9532 <returnvalue>interval</returnvalue>
9533 </para>
9534 <para>
9535 Adjust interval using <function>justify_days</function>
9536 and <function>justify_hours</function>, with additional sign
9537 adjustments
9538 </para>
9539 <para>
9540 <literal>justify_interval(interval '1 mon -1 hour')</literal>
9541 <returnvalue>29 days 23:00:00</returnvalue>
9542 </para></entry>
9543 </row>
9545 <row>
9546 <entry role="func_table_entry"><para role="func_signature">
9547 <indexterm>
9548 <primary>localtime</primary>
9549 </indexterm>
9550 <function>localtime</function>
9551 <returnvalue>time</returnvalue>
9552 </para>
9553 <para>
9554 Current time of day;
9555 see <xref linkend="functions-datetime-current"/>
9556 </para>
9557 <para>
9558 <literal>localtime</literal>
9559 <returnvalue>14:39:53.662522</returnvalue>
9560 </para></entry>
9561 </row>
9563 <row>
9564 <entry role="func_table_entry"><para role="func_signature">
9565 <function>localtime</function> ( <type>integer</type> )
9566 <returnvalue>time</returnvalue>
9567 </para>
9568 <para>
9569 Current time of day, with limited precision;
9570 see <xref linkend="functions-datetime-current"/>
9571 </para>
9572 <para>
9573 <literal>localtime(0)</literal>
9574 <returnvalue>14:39:53</returnvalue>
9575 </para></entry>
9576 </row>
9578 <row>
9579 <entry role="func_table_entry"><para role="func_signature">
9580 <indexterm>
9581 <primary>localtimestamp</primary>
9582 </indexterm>
9583 <function>localtimestamp</function>
9584 <returnvalue>timestamp</returnvalue>
9585 </para>
9586 <para>
9587 Current date and time (start of current transaction);
9588 see <xref linkend="functions-datetime-current"/>
9589 </para>
9590 <para>
9591 <literal>localtimestamp</literal>
9592 <returnvalue>2019-12-23 14:39:53.662522</returnvalue>
9593 </para></entry>
9594 </row>
9596 <row>
9597 <entry role="func_table_entry"><para role="func_signature">
9598 <function>localtimestamp</function> ( <type>integer</type> )
9599 <returnvalue>timestamp</returnvalue>
9600 </para>
9601 <para>
9602 Current date and time (start of current
9603 transaction), with limited precision;
9604 see <xref linkend="functions-datetime-current"/>
9605 </para>
9606 <para>
9607 <literal>localtimestamp(2)</literal>
9608 <returnvalue>2019-12-23 14:39:53.66</returnvalue>
9609 </para></entry>
9610 </row>
9612 <row>
9613 <entry role="func_table_entry"><para role="func_signature">
9614 <indexterm>
9615 <primary>make_date</primary>
9616 </indexterm>
9617 <function>make_date</function> ( <parameter>year</parameter> <type>int</type>,
9618 <parameter>month</parameter> <type>int</type>,
9619 <parameter>day</parameter> <type>int</type> )
9620 <returnvalue>date</returnvalue>
9621 </para>
9622 <para>
9623 Create date from year, month and day fields
9624 (negative years signify BC)
9625 </para>
9626 <para>
9627 <literal>make_date(2013, 7, 15)</literal>
9628 <returnvalue>2013-07-15</returnvalue>
9629 </para></entry>
9630 </row>
9632 <row>
9633 <entry role="func_table_entry"><para role="func_signature"><indexterm>
9634 <primary>make_interval</primary>
9635 </indexterm>
9636 <function>make_interval</function> ( <optional> <parameter>years</parameter> <type>int</type>
9637 <optional>, <parameter>months</parameter> <type>int</type>
9638 <optional>, <parameter>weeks</parameter> <type>int</type>
9639 <optional>, <parameter>days</parameter> <type>int</type>
9640 <optional>, <parameter>hours</parameter> <type>int</type>
9641 <optional>, <parameter>mins</parameter> <type>int</type>
9642 <optional>, <parameter>secs</parameter> <type>double precision</type>
9643 </optional></optional></optional></optional></optional></optional></optional> )
9644 <returnvalue>interval</returnvalue>
9645 </para>
9646 <para>
9647 Create interval from years, months, weeks, days, hours, minutes and
9648 seconds fields, each of which can default to zero
9649 </para>
9650 <para>
9651 <literal>make_interval(days =&gt; 10)</literal>
9652 <returnvalue>10 days</returnvalue>
9653 </para></entry>
9654 </row>
9656 <row>
9657 <entry role="func_table_entry"><para role="func_signature">
9658 <indexterm>
9659 <primary>make_time</primary>
9660 </indexterm>
9661 <function>make_time</function> ( <parameter>hour</parameter> <type>int</type>,
9662 <parameter>min</parameter> <type>int</type>,
9663 <parameter>sec</parameter> <type>double precision</type> )
9664 <returnvalue>time</returnvalue>
9665 </para>
9666 <para>
9667 Create time from hour, minute and seconds fields
9668 </para>
9669 <para>
9670 <literal>make_time(8, 15, 23.5)</literal>
9671 <returnvalue>08:15:23.5</returnvalue>
9672 </para></entry>
9673 </row>
9675 <row>
9676 <entry role="func_table_entry"><para role="func_signature">
9677 <indexterm>
9678 <primary>make_timestamp</primary>
9679 </indexterm>
9680 <function>make_timestamp</function> ( <parameter>year</parameter> <type>int</type>,
9681 <parameter>month</parameter> <type>int</type>,
9682 <parameter>day</parameter> <type>int</type>,
9683 <parameter>hour</parameter> <type>int</type>,
9684 <parameter>min</parameter> <type>int</type>,
9685 <parameter>sec</parameter> <type>double precision</type> )
9686 <returnvalue>timestamp</returnvalue>
9687 </para>
9688 <para>
9689 Create timestamp from year, month, day, hour, minute and seconds fields
9690 (negative years signify BC)
9691 </para>
9692 <para>
9693 <literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal>
9694 <returnvalue>2013-07-15 08:15:23.5</returnvalue>
9695 </para></entry>
9696 </row>
9698 <row>
9699 <entry role="func_table_entry"><para role="func_signature">
9700 <indexterm>
9701 <primary>make_timestamptz</primary>
9702 </indexterm>
9703 <function>make_timestamptz</function> ( <parameter>year</parameter> <type>int</type>,
9704 <parameter>month</parameter> <type>int</type>,
9705 <parameter>day</parameter> <type>int</type>,
9706 <parameter>hour</parameter> <type>int</type>,
9707 <parameter>min</parameter> <type>int</type>,
9708 <parameter>sec</parameter> <type>double precision</type>
9709 <optional>, <parameter>timezone</parameter> <type>text</type> </optional> )
9710 <returnvalue>timestamp with time zone</returnvalue>
9711 </para>
9712 <para>
9713 Create timestamp with time zone from year, month, day, hour, minute
9714 and seconds fields (negative years signify BC).
9715 If <parameter>timezone</parameter> is not
9716 specified, the current time zone is used; the examples assume the
9717 session time zone is <literal>Europe/London</literal>
9718 </para>
9719 <para>
9720 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal>
9721 <returnvalue>2013-07-15 08:15:23.5+01</returnvalue>
9722 </para>
9723 <para>
9724 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')</literal>
9725 <returnvalue>2013-07-15 13:15:23.5+01</returnvalue>
9726 </para></entry>
9727 </row>
9729 <row>
9730 <entry role="func_table_entry"><para role="func_signature">
9731 <indexterm>
9732 <primary>now</primary>
9733 </indexterm>
9734 <function>now</function> ( )
9735 <returnvalue>timestamp with time zone</returnvalue>
9736 </para>
9737 <para>
9738 Current date and time (start of current transaction);
9739 see <xref linkend="functions-datetime-current"/>
9740 </para>
9741 <para>
9742 <literal>now()</literal>
9743 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9744 </para></entry>
9745 </row>
9747 <row>
9748 <entry role="func_table_entry"><para role="func_signature">
9749 <indexterm>
9750 <primary>statement_timestamp</primary>
9751 </indexterm>
9752 <function>statement_timestamp</function> ( )
9753 <returnvalue>timestamp with time zone</returnvalue>
9754 </para>
9755 <para>
9756 Current date and time (start of current statement);
9757 see <xref linkend="functions-datetime-current"/>
9758 </para>
9759 <para>
9760 <literal>statement_timestamp()</literal>
9761 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9762 </para></entry>
9763 </row>
9765 <row>
9766 <entry role="func_table_entry"><para role="func_signature">
9767 <indexterm>
9768 <primary>timeofday</primary>
9769 </indexterm>
9770 <function>timeofday</function> ( )
9771 <returnvalue>text</returnvalue>
9772 </para>
9773 <para>
9774 Current date and time
9775 (like <function>clock_timestamp</function>, but as a <type>text</type> string);
9776 see <xref linkend="functions-datetime-current"/>
9777 </para>
9778 <para>
9779 <literal>timeofday()</literal>
9780 <returnvalue>Mon Dec 23 14:39:53.662522 2019 EST</returnvalue>
9781 </para></entry>
9782 </row>
9784 <row>
9785 <entry role="func_table_entry"><para role="func_signature">
9786 <indexterm>
9787 <primary>transaction_timestamp</primary>
9788 </indexterm>
9789 <function>transaction_timestamp</function> ( )
9790 <returnvalue>timestamp with time zone</returnvalue>
9791 </para>
9792 <para>
9793 Current date and time (start of current transaction);
9794 see <xref linkend="functions-datetime-current"/>
9795 </para>
9796 <para>
9797 <literal>transaction_timestamp()</literal>
9798 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9799 </para></entry>
9800 </row>
9802 <row>
9803 <entry role="func_table_entry"><para role="func_signature">
9804 <indexterm>
9805 <primary>to_timestamp</primary>
9806 </indexterm>
9807 <function>to_timestamp</function> ( <type>double precision</type> )
9808 <returnvalue>timestamp with time zone</returnvalue>
9809 </para>
9810 <para>
9811 Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
9812 timestamp with time zone
9813 </para>
9814 <para>
9815 <literal>to_timestamp(1284352323)</literal>
9816 <returnvalue>2010-09-13 04:32:03+00</returnvalue>
9817 </para></entry>
9818 </row>
9819 </tbody>
9820 </tgroup>
9821 </table>
9823 <para>
9824 <indexterm>
9825 <primary>OVERLAPS</primary>
9826 </indexterm>
9827 In addition to these functions, the SQL <literal>OVERLAPS</literal> operator is
9828 supported:
9829 <synopsis>
9830 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
9831 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
9832 </synopsis>
9833 This expression yields true when two time periods (defined by their
9834 endpoints) overlap, false when they do not overlap. The endpoints
9835 can be specified as pairs of dates, times, or time stamps; or as
9836 a date, time, or time stamp followed by an interval. When a pair
9837 of values is provided, either the start or the end can be written
9838 first; <literal>OVERLAPS</literal> automatically takes the earlier value
9839 of the pair as the start. Each time period is considered to
9840 represent the half-open interval <replaceable>start</replaceable> <literal>&lt;=</literal>
9841 <replaceable>time</replaceable> <literal>&lt;</literal> <replaceable>end</replaceable>, unless
9842 <replaceable>start</replaceable> and <replaceable>end</replaceable> are equal in which case it
9843 represents that single time instant. This means for instance that two
9844 time periods with only an endpoint in common do not overlap.
9845 </para>
9847 <screen>
9848 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
9849 (DATE '2001-10-30', DATE '2002-10-30');
9850 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
9851 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
9852 (DATE '2001-10-30', DATE '2002-10-30');
9853 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
9854 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
9855 (DATE '2001-10-30', DATE '2001-10-31');
9856 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
9857 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
9858 (DATE '2001-10-30', DATE '2001-10-31');
9859 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
9860 </screen>
9862 <para>
9863 When adding an <type>interval</type> value to (or subtracting an
9864 <type>interval</type> value from) a <type>timestamp</type>
9865 or <type>timestamp with time zone</type> value, the months, days, and
9866 microseconds fields of the <type>interval</type> value are handled in turn.
9867 First, a nonzero months field advances or decrements the date of the
9868 timestamp by the indicated number of months, keeping the day of month the
9869 same unless it would be past the end of the new month, in which case the
9870 last day of that month is used. (For example, March 31 plus 1 month
9871 becomes April 30, but March 31 plus 2 months becomes May 31.)
9872 Then the days field advances or decrements the date of the timestamp by
9873 the indicated number of days. In both these steps the local time of day
9874 is kept the same. Finally, if there is a nonzero microseconds field, it
9875 is added or subtracted literally.
9876 When doing arithmetic on a <type>timestamp with time zone</type> value in
9877 a time zone that recognizes DST, this means that adding or subtracting
9878 (say) <literal>interval '1 day'</literal> does not necessarily have the
9879 same result as adding or subtracting <literal>interval '24
9880 hours'</literal>.
9881 For example, with the session time zone set
9882 to <literal>America/Denver</literal>:
9883 <screen>
9884 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day';
9885 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 12:00:00-06</computeroutput>
9886 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours';
9887 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 13:00:00-06</computeroutput>
9888 </screen>
9889 This happens because an hour was skipped due to a change in daylight saving
9890 time at <literal>2005-04-03 02:00:00</literal> in time zone
9891 <literal>America/Denver</literal>.
9892 </para>
9894 <para>
9895 Note there can be ambiguity in the <literal>months</literal> field returned by
9896 <function>age</function> because different months have different numbers of
9897 days. <productname>PostgreSQL</productname>'s approach uses the month from the
9898 earlier of the two dates when calculating partial months. For example,
9899 <literal>age('2004-06-01', '2004-04-30')</literal> uses April to yield
9900 <literal>1 mon 1 day</literal>, while using May would yield <literal>1 mon 2
9901 days</literal> because May has 31 days, while April has only 30.
9902 </para>
9904 <para>
9905 Subtraction of dates and timestamps can also be complex. One conceptually
9906 simple way to perform subtraction is to convert each value to a number
9907 of seconds using <literal>EXTRACT(EPOCH FROM ...)</literal>, then subtract the
9908 results; this produces the
9909 number of <emphasis>seconds</emphasis> between the two values. This will adjust
9910 for the number of days in each month, timezone changes, and daylight
9911 saving time adjustments. Subtraction of date or timestamp
9912 values with the <quote><literal>-</literal></quote> operator
9913 returns the number of days (24-hours) and hours/minutes/seconds
9914 between the values, making the same adjustments. The <function>age</function>
9915 function returns years, months, days, and hours/minutes/seconds,
9916 performing field-by-field subtraction and then adjusting for negative
9917 field values. The following queries illustrate the differences in these
9918 approaches. The sample results were produced with <literal>timezone
9919 = 'US/Eastern'</literal>; there is a daylight saving time change between the
9920 two dates used:
9921 </para>
9923 <screen>
9924 SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
9925 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
9926 <lineannotation>Result: </lineannotation><computeroutput>10537200.000000</computeroutput>
9927 SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
9928 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
9929 / 60 / 60 / 24;
9930 <lineannotation>Result: </lineannotation><computeroutput>121.9583333333333333</computeroutput>
9931 SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
9932 <lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
9933 SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
9934 <lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
9935 </screen>
9937 <sect2 id="functions-datetime-extract">
9938 <title><function>EXTRACT</function>, <function>date_part</function></title>
9940 <indexterm>
9941 <primary>date_part</primary>
9942 </indexterm>
9943 <indexterm>
9944 <primary>extract</primary>
9945 </indexterm>
9947 <synopsis>
9948 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
9949 </synopsis>
9951 <para>
9952 The <function>extract</function> function retrieves subfields
9953 such as year or hour from date/time values.
9954 <replaceable>source</replaceable> must be a value expression of
9955 type <type>timestamp</type>, <type>date</type>, <type>time</type>,
9956 or <type>interval</type>. (Timestamps and times can be with or
9957 without time zone.)
9958 <replaceable>field</replaceable> is an identifier or
9959 string that selects what field to extract from the source value.
9960 Not all fields are valid for every input data type; for example, fields
9961 smaller than a day cannot be extracted from a <type>date</type>, while
9962 fields of a day or more cannot be extracted from a <type>time</type>.
9963 The <function>extract</function> function returns values of type
9964 <type>numeric</type>.
9965 </para>
9967 <para>
9968 The following are valid field names:
9970 <!-- alphabetical -->
9971 <variablelist>
9972 <varlistentry>
9973 <term><literal>century</literal></term>
9974 <listitem>
9975 <para>
9976 The century; for <type>interval</type> values, the year field
9977 divided by 100
9978 </para>
9980 <screen>
9981 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
9982 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
9983 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
9984 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
9985 SELECT EXTRACT(CENTURY FROM DATE '0001-01-01 AD');
9986 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
9987 SELECT EXTRACT(CENTURY FROM DATE '0001-12-31 BC');
9988 <lineannotation>Result: </lineannotation><computeroutput>-1</computeroutput>
9989 SELECT EXTRACT(CENTURY FROM INTERVAL '2001 years');
9990 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
9991 </screen>
9992 </listitem>
9993 </varlistentry>
9995 <varlistentry>
9996 <term><literal>day</literal></term>
9997 <listitem>
9998 <para>
9999 The day of the month (1&ndash;31); for <type>interval</type>
10000 values, the number of days
10001 </para>
10003 <screen>
10004 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
10005 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
10006 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
10007 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
10008 </screen>
10010 </listitem>
10011 </varlistentry>
10013 <varlistentry>
10014 <term><literal>decade</literal></term>
10015 <listitem>
10016 <para>
10017 The year field divided by 10
10018 </para>
10020 <screen>
10021 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
10022 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
10023 </screen>
10024 </listitem>
10025 </varlistentry>
10027 <varlistentry>
10028 <term><literal>dow</literal></term>
10029 <listitem>
10030 <para>
10031 The day of the week as Sunday (<literal>0</literal>) to
10032 Saturday (<literal>6</literal>)
10033 </para>
10035 <screen>
10036 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
10037 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
10038 </screen>
10039 <para>
10040 Note that <function>extract</function>'s day of the week numbering
10041 differs from that of the <function>to_char(...,
10042 'D')</function> function.
10043 </para>
10045 </listitem>
10046 </varlistentry>
10048 <varlistentry>
10049 <term><literal>doy</literal></term>
10050 <listitem>
10051 <para>
10052 The day of the year (1&ndash;365/366)
10053 </para>
10055 <screen>
10056 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
10057 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
10058 </screen>
10059 </listitem>
10060 </varlistentry>
10062 <varlistentry>
10063 <term><literal>epoch</literal></term>
10064 <listitem>
10065 <para>
10066 For <type>timestamp with time zone</type> values, the
10067 number of seconds since 1970-01-01 00:00:00 UTC (negative for
10068 timestamps before that);
10069 for <type>date</type> and <type>timestamp</type> values, the
10070 nominal number of seconds since 1970-01-01 00:00:00,
10071 without regard to timezone or daylight-savings rules;
10072 for <type>interval</type> values, the total number
10073 of seconds in the interval
10074 </para>
10076 <screen>
10077 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
10078 <lineannotation>Result: </lineannotation><computeroutput>982384720.120000</computeroutput>
10079 SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12');
10080 <lineannotation>Result: </lineannotation><computeroutput>982355920.120000</computeroutput>
10081 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
10082 <lineannotation>Result: </lineannotation><computeroutput>442800.000000</computeroutput>
10083 </screen>
10085 <para>
10086 You can convert an epoch value back to a <type>timestamp with time zone</type>
10087 with <function>to_timestamp</function>:
10088 </para>
10089 <screen>
10090 SELECT to_timestamp(982384720.12);
10091 <lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput>
10092 </screen>
10094 <para>
10095 Beware that applying <function>to_timestamp</function> to an epoch
10096 extracted from a <type>date</type> or <type>timestamp</type> value
10097 could produce a misleading result: the result will effectively
10098 assume that the original value had been given in UTC, which might
10099 not be the case.
10100 </para>
10101 </listitem>
10102 </varlistentry>
10104 <varlistentry>
10105 <term><literal>hour</literal></term>
10106 <listitem>
10107 <para>
10108 The hour field (0&ndash;23 in timestamps, unrestricted in
10109 intervals)
10110 </para>
10112 <screen>
10113 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
10114 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10115 </screen>
10116 </listitem>
10117 </varlistentry>
10119 <varlistentry>
10120 <term><literal>isodow</literal></term>
10121 <listitem>
10122 <para>
10123 The day of the week as Monday (<literal>1</literal>) to
10124 Sunday (<literal>7</literal>)
10125 </para>
10127 <screen>
10128 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
10129 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10130 </screen>
10131 <para>
10132 This is identical to <literal>dow</literal> except for Sunday. This
10133 matches the <acronym>ISO</acronym> 8601 day of the week numbering.
10134 </para>
10136 </listitem>
10137 </varlistentry>
10139 <varlistentry>
10140 <term><literal>isoyear</literal></term>
10141 <listitem>
10142 <para>
10143 The <acronym>ISO</acronym> 8601 week-numbering year that the date
10144 falls in
10145 </para>
10147 <screen>
10148 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
10149 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
10150 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
10151 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
10152 </screen>
10154 <para>
10155 Each <acronym>ISO</acronym> 8601 week-numbering year begins with the
10156 Monday of the week containing the 4th of January, so in early
10157 January or late December the <acronym>ISO</acronym> year may be
10158 different from the Gregorian year. See the <literal>week</literal>
10159 field for more information.
10160 </para>
10161 </listitem>
10162 </varlistentry>
10164 <varlistentry>
10165 <term><literal>julian</literal></term>
10166 <listitem>
10167 <para>
10168 The <firstterm>Julian Date</firstterm> corresponding to the
10169 date or timestamp. Timestamps
10170 that are not local midnight result in a fractional value. See
10171 <xref linkend="datetime-julian-dates"/> for more information.
10172 </para>
10174 <screen>
10175 SELECT EXTRACT(JULIAN FROM DATE '2006-01-01');
10176 <lineannotation>Result: </lineannotation><computeroutput>2453737</computeroutput>
10177 SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00');
10178 <lineannotation>Result: </lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
10179 </screen>
10180 </listitem>
10181 </varlistentry>
10183 <varlistentry>
10184 <term><literal>microseconds</literal></term>
10185 <listitem>
10186 <para>
10187 The seconds field, including fractional parts, multiplied by 1
10188 000 000; note that this includes full seconds
10189 </para>
10191 <screen>
10192 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
10193 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
10194 </screen>
10195 </listitem>
10196 </varlistentry>
10198 <varlistentry>
10199 <term><literal>millennium</literal></term>
10200 <listitem>
10201 <para>
10202 The millennium; for <type>interval</type> values, the year field
10203 divided by 1000
10204 </para>
10206 <screen>
10207 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
10208 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10209 SELECT EXTRACT(MILLENNIUM FROM INTERVAL '2001 years');
10210 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
10211 </screen>
10213 <para>
10214 Years in the 1900s are in the second millennium.
10215 The third millennium started January 1, 2001.
10216 </para>
10217 </listitem>
10218 </varlistentry>
10220 <varlistentry>
10221 <term><literal>milliseconds</literal></term>
10222 <listitem>
10223 <para>
10224 The seconds field, including fractional parts, multiplied by
10225 1000. Note that this includes full seconds.
10226 </para>
10228 <screen>
10229 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
10230 <lineannotation>Result: </lineannotation><computeroutput>28500.000</computeroutput>
10231 </screen>
10232 </listitem>
10233 </varlistentry>
10235 <varlistentry>
10236 <term><literal>minute</literal></term>
10237 <listitem>
10238 <para>
10239 The minutes field (0&ndash;59)
10240 </para>
10242 <screen>
10243 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
10244 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
10245 </screen>
10246 </listitem>
10247 </varlistentry>
10249 <varlistentry>
10250 <term><literal>month</literal></term>
10251 <listitem>
10252 <para>
10253 The number of the month within the year (1&ndash;12);
10254 for <type>interval</type> values, the number of months modulo 12
10255 (0&ndash;11)
10256 </para>
10258 <screen>
10259 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
10260 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
10261 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
10262 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10263 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
10264 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10265 </screen>
10266 </listitem>
10267 </varlistentry>
10269 <varlistentry>
10270 <term><literal>quarter</literal></term>
10271 <listitem>
10272 <para>
10273 The quarter of the year (1&ndash;4) that the date is in
10274 </para>
10276 <screen>
10277 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
10278 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10279 </screen>
10280 </listitem>
10281 </varlistentry>
10283 <varlistentry>
10284 <term><literal>second</literal></term>
10285 <listitem>
10286 <para>
10287 The seconds field, including any fractional seconds
10288 </para>
10290 <screen>
10291 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
10292 <lineannotation>Result: </lineannotation><computeroutput>40.000000</computeroutput>
10293 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
10294 <lineannotation>Result: </lineannotation><computeroutput>28.500000</computeroutput>
10295 </screen>
10296 </listitem>
10297 </varlistentry>
10298 <varlistentry>
10299 <term><literal>timezone</literal></term>
10300 <listitem>
10301 <para>
10302 The time zone offset from UTC, measured in seconds. Positive values
10303 correspond to time zones east of UTC, negative values to
10304 zones west of UTC. (Technically,
10305 <productname>PostgreSQL</productname> does not use UTC because
10306 leap seconds are not handled.)
10307 </para>
10308 </listitem>
10309 </varlistentry>
10311 <varlistentry>
10312 <term><literal>timezone_hour</literal></term>
10313 <listitem>
10314 <para>
10315 The hour component of the time zone offset
10316 </para>
10317 </listitem>
10318 </varlistentry>
10320 <varlistentry>
10321 <term><literal>timezone_minute</literal></term>
10322 <listitem>
10323 <para>
10324 The minute component of the time zone offset
10325 </para>
10326 </listitem>
10327 </varlistentry>
10329 <varlistentry>
10330 <term><literal>week</literal></term>
10331 <listitem>
10332 <para>
10333 The number of the <acronym>ISO</acronym> 8601 week-numbering week of
10334 the year. By definition, ISO weeks start on Mondays and the first
10335 week of a year contains January 4 of that year. In other words, the
10336 first Thursday of a year is in week 1 of that year.
10337 </para>
10338 <para>
10339 In the ISO week-numbering system, it is possible for early-January
10340 dates to be part of the 52nd or 53rd week of the previous year, and for
10341 late-December dates to be part of the first week of the next year.
10342 For example, <literal>2005-01-01</literal> is part of the 53rd week of year
10343 2004, and <literal>2006-01-01</literal> is part of the 52nd week of year
10344 2005, while <literal>2012-12-31</literal> is part of the first week of 2013.
10345 It's recommended to use the <literal>isoyear</literal> field together with
10346 <literal>week</literal> to get consistent results.
10347 </para>
10349 <screen>
10350 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
10351 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10352 </screen>
10353 </listitem>
10354 </varlistentry>
10356 <varlistentry>
10357 <term><literal>year</literal></term>
10358 <listitem>
10359 <para>
10360 The year field. Keep in mind there is no <literal>0 AD</literal>, so subtracting
10361 <literal>BC</literal> years from <literal>AD</literal> years should be done with care.
10362 </para>
10364 <screen>
10365 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
10366 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
10367 </screen>
10368 </listitem>
10369 </varlistentry>
10371 </variablelist>
10372 </para>
10374 <para>
10375 When processing an <type>interval</type> value,
10376 the <function>extract</function> function produces field values that
10377 match the interpretation used by the interval output function. This
10378 can produce surprising results if one starts with a non-normalized
10379 interval representation, for example:
10380 <screen>
10381 SELECT INTERVAL '80 minutes';
10382 <lineannotation>Result: </lineannotation><computeroutput>01:20:00</computeroutput>
10383 SELECT EXTRACT(MINUTES FROM INTERVAL '80 minutes');
10384 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10385 </screen>
10386 </para>
10388 <note>
10389 <para>
10390 When the input value is +/-Infinity, <function>extract</function> returns
10391 +/-Infinity for monotonically-increasing fields (<literal>epoch</literal>,
10392 <literal>julian</literal>, <literal>year</literal>, <literal>isoyear</literal>,
10393 <literal>decade</literal>, <literal>century</literal>, and <literal>millennium</literal>).
10394 For other fields, NULL is returned. <productname>PostgreSQL</productname>
10395 versions before 9.6 returned zero for all cases of infinite input.
10396 </para>
10397 </note>
10399 <para>
10400 The <function>extract</function> function is primarily intended
10401 for computational processing. For formatting date/time values for
10402 display, see <xref linkend="functions-formatting"/>.
10403 </para>
10405 <para>
10406 The <function>date_part</function> function is modeled on the traditional
10407 <productname>Ingres</productname> equivalent to the
10408 <acronym>SQL</acronym>-standard function <function>extract</function>:
10409 <synopsis>
10410 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
10411 </synopsis>
10412 Note that here the <replaceable>field</replaceable> parameter needs to
10413 be a string value, not a name. The valid field names for
10414 <function>date_part</function> are the same as for
10415 <function>extract</function>.
10416 For historical reasons, the <function>date_part</function> function
10417 returns values of type <type>double precision</type>. This can result in
10418 a loss of precision in certain uses. Using <function>extract</function>
10419 is recommended instead.
10420 </para>
10422 <screen>
10423 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
10424 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
10425 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
10426 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
10427 </screen>
10429 </sect2>
10431 <sect2 id="functions-datetime-trunc">
10432 <title><function>date_trunc</function></title>
10434 <indexterm>
10435 <primary>date_trunc</primary>
10436 </indexterm>
10438 <para>
10439 The function <function>date_trunc</function> is conceptually
10440 similar to the <function>trunc</function> function for numbers.
10441 </para>
10443 <para>
10444 <synopsis>
10445 date_trunc(<replaceable>field</replaceable>, <replaceable>source</replaceable> [, <replaceable>time_zone</replaceable> ])
10446 </synopsis>
10447 <replaceable>source</replaceable> is a value expression of type
10448 <type>timestamp</type>, <type>timestamp with time zone</type>,
10449 or <type>interval</type>.
10450 (Values of type <type>date</type> and
10451 <type>time</type> are cast automatically to <type>timestamp</type> or
10452 <type>interval</type>, respectively.)
10453 <replaceable>field</replaceable> selects to which precision to
10454 truncate the input value. The return value is likewise of type
10455 <type>timestamp</type>, <type>timestamp with time zone</type>,
10456 or <type>interval</type>,
10457 and it has all fields that are less significant than the
10458 selected one set to zero (or one, for day and month).
10459 </para>
10461 <para>
10462 Valid values for <replaceable>field</replaceable> are:
10463 <simplelist>
10464 <member><literal>microseconds</literal></member>
10465 <member><literal>milliseconds</literal></member>
10466 <member><literal>second</literal></member>
10467 <member><literal>minute</literal></member>
10468 <member><literal>hour</literal></member>
10469 <member><literal>day</literal></member>
10470 <member><literal>week</literal></member>
10471 <member><literal>month</literal></member>
10472 <member><literal>quarter</literal></member>
10473 <member><literal>year</literal></member>
10474 <member><literal>decade</literal></member>
10475 <member><literal>century</literal></member>
10476 <member><literal>millennium</literal></member>
10477 </simplelist>
10478 </para>
10480 <para>
10481 When the input value is of type <type>timestamp with time zone</type>,
10482 the truncation is performed with respect to a particular time zone;
10483 for example, truncation to <literal>day</literal> produces a value that
10484 is midnight in that zone. By default, truncation is done with respect
10485 to the current <xref linkend="guc-timezone"/> setting, but the
10486 optional <replaceable>time_zone</replaceable> argument can be provided
10487 to specify a different time zone. The time zone name can be specified
10488 in any of the ways described in <xref linkend="datatype-timezones"/>.
10489 </para>
10491 <para>
10492 A time zone cannot be specified when processing <type>timestamp without
10493 time zone</type> or <type>interval</type> inputs. These are always
10494 taken at face value.
10495 </para>
10497 <para>
10498 Examples (assuming the local time zone is <literal>America/New_York</literal>):
10499 <screen>
10500 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
10501 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
10502 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
10503 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
10504 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
10505 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput>
10506 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
10507 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput>
10508 SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
10509 <lineannotation>Result: </lineannotation><computeroutput>3 days 02:00:00</computeroutput>
10510 </screen>
10511 </para>
10512 </sect2>
10514 <sect2 id="functions-datetime-bin">
10515 <title><function>date_bin</function></title>
10517 <indexterm>
10518 <primary>date_bin</primary>
10519 </indexterm>
10521 <para>
10522 The function <function>date_bin</function> <quote>bins</quote> the input
10523 timestamp into the specified interval (the <firstterm>stride</firstterm>)
10524 aligned with a specified origin.
10525 </para>
10527 <para>
10528 <synopsis>
10529 date_bin(<replaceable>stride</replaceable>, <replaceable>source</replaceable>, <replaceable>origin</replaceable>)
10530 </synopsis>
10531 <replaceable>source</replaceable> is a value expression of type
10532 <type>timestamp</type> or <type>timestamp with time zone</type>. (Values
10533 of type <type>date</type> are cast automatically to
10534 <type>timestamp</type>.) <replaceable>stride</replaceable> is a value
10535 expression of type <type>interval</type>. The return value is likewise
10536 of type <type>timestamp</type> or <type>timestamp with time zone</type>,
10537 and it marks the beginning of the bin into which the
10538 <replaceable>source</replaceable> is placed.
10539 </para>
10541 <para>
10542 Examples:
10543 <screen>
10544 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01');
10545 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:30:00</computeroutput>
10546 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30');
10547 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:32:30</computeroutput>
10548 </screen>
10549 </para>
10551 <para>
10552 In the case of full units (1 minute, 1 hour, etc.), it gives the same result as
10553 the analogous <function>date_trunc</function> call, but the difference is
10554 that <function>date_bin</function> can truncate to an arbitrary interval.
10555 </para>
10557 <para>
10558 The <parameter>stride</parameter> interval must be greater than zero and
10559 cannot contain units of month or larger.
10560 </para>
10561 </sect2>
10563 <sect2 id="functions-datetime-zoneconvert">
10564 <title><literal>AT TIME ZONE</literal></title>
10566 <indexterm>
10567 <primary>time zone</primary>
10568 <secondary>conversion</secondary>
10569 </indexterm>
10571 <indexterm>
10572 <primary>AT TIME ZONE</primary>
10573 </indexterm>
10575 <para>
10576 The <literal>AT TIME ZONE</literal> operator converts time
10577 stamp <emphasis>without</emphasis> time zone to/from
10578 time stamp <emphasis>with</emphasis> time zone, and
10579 <type>time with time zone</type> values to different time
10580 zones. <xref linkend="functions-datetime-zoneconvert-table"/> shows its
10581 variants.
10582 </para>
10584 <table id="functions-datetime-zoneconvert-table">
10585 <title><literal>AT TIME ZONE</literal> Variants</title>
10586 <tgroup cols="1">
10587 <thead>
10588 <row>
10589 <entry role="func_table_entry"><para role="func_signature">
10590 Operator
10591 </para>
10592 <para>
10593 Description
10594 </para>
10595 <para>
10596 Example(s)
10597 </para></entry>
10598 </row>
10599 </thead>
10601 <tbody>
10602 <row>
10603 <entry role="func_table_entry"><para role="func_signature">
10604 <type>timestamp without time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10605 <returnvalue>timestamp with time zone</returnvalue>
10606 </para>
10607 <para>
10608 Converts given time stamp <emphasis>without</emphasis> time zone to
10609 time stamp <emphasis>with</emphasis> time zone, assuming the given
10610 value is in the named time zone.
10611 </para>
10612 <para>
10613 <literal>timestamp '2001-02-16 20:38:40' at time zone 'America/Denver'</literal>
10614 <returnvalue>2001-02-17 03:38:40+00</returnvalue>
10615 </para></entry>
10616 </row>
10618 <row>
10619 <entry role="func_table_entry"><para role="func_signature">
10620 <type>timestamp with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10621 <returnvalue>timestamp without time zone</returnvalue>
10622 </para>
10623 <para>
10624 Converts given time stamp <emphasis>with</emphasis> time zone to
10625 time stamp <emphasis>without</emphasis> time zone, as the time would
10626 appear in that zone.
10627 </para>
10628 <para>
10629 <literal>timestamp with time zone '2001-02-16 20:38:40-05' at time zone 'America/Denver'</literal>
10630 <returnvalue>2001-02-16 18:38:40</returnvalue>
10631 </para></entry>
10632 </row>
10634 <row>
10635 <entry role="func_table_entry"><para role="func_signature">
10636 <type>time with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10637 <returnvalue>time with time zone</returnvalue>
10638 </para>
10639 <para>
10640 Converts given time <emphasis>with</emphasis> time zone to a new time
10641 zone. Since no date is supplied, this uses the currently active UTC
10642 offset for the named destination zone.
10643 </para>
10644 <para>
10645 <literal>time with time zone '05:34:17-05' at time zone 'UTC'</literal>
10646 <returnvalue>10:34:17+00</returnvalue>
10647 </para></entry>
10648 </row>
10649 </tbody>
10650 </tgroup>
10651 </table>
10653 <para>
10654 In these expressions, the desired time zone <replaceable>zone</replaceable> can be
10655 specified either as a text value (e.g., <literal>'America/Los_Angeles'</literal>)
10656 or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
10657 In the text case, a time zone name can be specified in any of the ways
10658 described in <xref linkend="datatype-timezones"/>.
10659 The interval case is only useful for zones that have fixed offsets from
10660 UTC, so it is not very common in practice.
10661 </para>
10663 <para>
10664 Examples (assuming the current <xref linkend="guc-timezone"/> setting
10665 is <literal>America/Los_Angeles</literal>):
10666 <screen>
10667 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
10668 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
10669 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/Denver';
10670 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
10671 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
10672 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 05:38:40</computeroutput>
10673 </screen>
10674 The first example adds a time zone to a value that lacks it, and
10675 displays the value using the current <varname>TimeZone</varname>
10676 setting. The second example shifts the time stamp with time zone value
10677 to the specified time zone, and returns the value without a time zone.
10678 This allows storage and display of values different from the current
10679 <varname>TimeZone</varname> setting. The third example converts
10680 Tokyo time to Chicago time.
10681 </para>
10683 <para>
10684 The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
10685 <replaceable>timestamp</replaceable>)</literal> is equivalent to the SQL-conforming construct
10686 <literal><replaceable>timestamp</replaceable> AT TIME ZONE
10687 <replaceable>zone</replaceable></literal>.
10688 </para>
10689 </sect2>
10691 <sect2 id="functions-datetime-current">
10692 <title>Current Date/Time</title>
10694 <indexterm>
10695 <primary>date</primary>
10696 <secondary>current</secondary>
10697 </indexterm>
10699 <indexterm>
10700 <primary>time</primary>
10701 <secondary>current</secondary>
10702 </indexterm>
10704 <para>
10705 <productname>PostgreSQL</productname> provides a number of functions
10706 that return values related to the current date and time. These
10707 SQL-standard functions all return values based on the start time of
10708 the current transaction:
10709 <synopsis>
10710 CURRENT_DATE
10711 CURRENT_TIME
10712 CURRENT_TIMESTAMP
10713 CURRENT_TIME(<replaceable>precision</replaceable>)
10714 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
10715 LOCALTIME
10716 LOCALTIMESTAMP
10717 LOCALTIME(<replaceable>precision</replaceable>)
10718 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
10719 </synopsis>
10720 </para>
10722 <para>
10723 <function>CURRENT_TIME</function> and
10724 <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
10725 <function>LOCALTIME</function> and
10726 <function>LOCALTIMESTAMP</function> deliver values without time zone.
10727 </para>
10729 <para>
10730 <function>CURRENT_TIME</function>,
10731 <function>CURRENT_TIMESTAMP</function>,
10732 <function>LOCALTIME</function>, and
10733 <function>LOCALTIMESTAMP</function>
10734 can optionally take
10735 a precision parameter, which causes the result to be rounded
10736 to that many fractional digits in the seconds field. Without a precision parameter,
10737 the result is given to the full available precision.
10738 </para>
10740 <para>
10741 Some examples:
10742 <screen>
10743 SELECT CURRENT_TIME;
10744 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
10745 SELECT CURRENT_DATE;
10746 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23</computeroutput>
10747 SELECT CURRENT_TIMESTAMP;
10748 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522-05</computeroutput>
10749 SELECT CURRENT_TIMESTAMP(2);
10750 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.66-05</computeroutput>
10751 SELECT LOCALTIMESTAMP;
10752 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522</computeroutput>
10753 </screen>
10754 </para>
10756 <para>
10757 Since these functions return
10758 the start time of the current transaction, their values do not
10759 change during the transaction. This is considered a feature:
10760 the intent is to allow a single transaction to have a consistent
10761 notion of the <quote>current</quote> time, so that multiple
10762 modifications within the same transaction bear the same
10763 time stamp.
10764 </para>
10766 <note>
10767 <para>
10768 Other database systems might advance these values more
10769 frequently.
10770 </para>
10771 </note>
10773 <para>
10774 <productname>PostgreSQL</productname> also provides functions that
10775 return the start time of the current statement, as well as the actual
10776 current time at the instant the function is called. The complete list
10777 of non-SQL-standard time functions is:
10778 <synopsis>
10779 transaction_timestamp()
10780 statement_timestamp()
10781 clock_timestamp()
10782 timeofday()
10783 now()
10784 </synopsis>
10785 </para>
10787 <para>
10788 <function>transaction_timestamp()</function> is equivalent to
10789 <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
10790 what it returns.
10791 <function>statement_timestamp()</function> returns the start time of the current
10792 statement (more specifically, the time of receipt of the latest command
10793 message from the client).
10794 <function>statement_timestamp()</function> and <function>transaction_timestamp()</function>
10795 return the same value during the first command of a transaction, but might
10796 differ during subsequent commands.
10797 <function>clock_timestamp()</function> returns the actual current time, and
10798 therefore its value changes even within a single SQL command.
10799 <function>timeofday()</function> is a historical
10800 <productname>PostgreSQL</productname> function. Like
10801 <function>clock_timestamp()</function>, it returns the actual current time,
10802 but as a formatted <type>text</type> string rather than a <type>timestamp
10803 with time zone</type> value.
10804 <function>now()</function> is a traditional <productname>PostgreSQL</productname>
10805 equivalent to <function>transaction_timestamp()</function>.
10806 </para>
10808 <para>
10809 All the date/time data types also accept the special literal value
10810 <literal>now</literal> to specify the current date and time (again,
10811 interpreted as the transaction start time). Thus,
10812 the following three all return the same result:
10813 <programlisting>
10814 SELECT CURRENT_TIMESTAMP;
10815 SELECT now();
10816 SELECT TIMESTAMP 'now'; -- but see tip below
10817 </programlisting>
10818 </para>
10820 <tip>
10821 <para>
10822 Do not use the third form when specifying a value to be evaluated later,
10823 for example in a <literal>DEFAULT</literal> clause for a table column.
10824 The system will convert <literal>now</literal>
10825 to a <type>timestamp</type> as soon as the constant is parsed, so that when
10826 the default value is needed,
10827 the time of the table creation would be used! The first two
10828 forms will not be evaluated until the default value is used,
10829 because they are function calls. Thus they will give the desired
10830 behavior of defaulting to the time of row insertion.
10831 (See also <xref linkend="datatype-datetime-special-values"/>.)
10832 </para>
10833 </tip>
10834 </sect2>
10836 <sect2 id="functions-datetime-delay">
10837 <title>Delaying Execution</title>
10839 <indexterm>
10840 <primary>pg_sleep</primary>
10841 </indexterm>
10842 <indexterm>
10843 <primary>pg_sleep_for</primary>
10844 </indexterm>
10845 <indexterm>
10846 <primary>pg_sleep_until</primary>
10847 </indexterm>
10848 <indexterm>
10849 <primary>sleep</primary>
10850 </indexterm>
10851 <indexterm>
10852 <primary>delay</primary>
10853 </indexterm>
10855 <para>
10856 The following functions are available to delay execution of the server
10857 process:
10858 <synopsis>
10859 pg_sleep ( <type>double precision</type> )
10860 pg_sleep_for ( <type>interval</type> )
10861 pg_sleep_until ( <type>timestamp with time zone</type> )
10862 </synopsis>
10864 <function>pg_sleep</function> makes the current session's process
10865 sleep until the given number of seconds have
10866 elapsed. Fractional-second delays can be specified.
10867 <function>pg_sleep_for</function> is a convenience function to
10868 allow the sleep time to be specified as an <type>interval</type>.
10869 <function>pg_sleep_until</function> is a convenience function for when
10870 a specific wake-up time is desired.
10871 For example:
10873 <programlisting>
10874 SELECT pg_sleep(1.5);
10875 SELECT pg_sleep_for('5 minutes');
10876 SELECT pg_sleep_until('tomorrow 03:00');
10877 </programlisting>
10878 </para>
10880 <note>
10881 <para>
10882 The effective resolution of the sleep interval is platform-specific;
10883 0.01 seconds is a common value. The sleep delay will be at least as long
10884 as specified. It might be longer depending on factors such as server load.
10885 In particular, <function>pg_sleep_until</function> is not guaranteed to
10886 wake up exactly at the specified time, but it will not wake up any earlier.
10887 </para>
10888 </note>
10890 <warning>
10891 <para>
10892 Make sure that your session does not hold more locks than necessary
10893 when calling <function>pg_sleep</function> or its variants. Otherwise
10894 other sessions might have to wait for your sleeping process, slowing down
10895 the entire system.
10896 </para>
10897 </warning>
10898 </sect2>
10900 </sect1>
10903 <sect1 id="functions-enum">
10904 <title>Enum Support Functions</title>
10906 <para>
10907 For enum types (described in <xref linkend="datatype-enum"/>),
10908 there are several functions that allow cleaner programming without
10909 hard-coding particular values of an enum type.
10910 These are listed in <xref linkend="functions-enum-table"/>. The examples
10911 assume an enum type created as:
10913 <programlisting>
10914 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
10915 </programlisting>
10917 </para>
10919 <table id="functions-enum-table">
10920 <title>Enum Support Functions</title>
10921 <tgroup cols="1">
10922 <thead>
10923 <row>
10924 <entry role="func_table_entry"><para role="func_signature">
10925 Function
10926 </para>
10927 <para>
10928 Description
10929 </para>
10930 <para>
10931 Example(s)
10932 </para></entry>
10933 </row>
10934 </thead>
10936 <tbody>
10937 <row>
10938 <entry role="func_table_entry"><para role="func_signature">
10939 <indexterm>
10940 <primary>enum_first</primary>
10941 </indexterm>
10942 <function>enum_first</function> ( <type>anyenum</type> )
10943 <returnvalue>anyenum</returnvalue>
10944 </para>
10945 <para>
10946 Returns the first value of the input enum type.
10947 </para>
10948 <para>
10949 <literal>enum_first(null::rainbow)</literal>
10950 <returnvalue>red</returnvalue>
10951 </para></entry>
10952 </row>
10953 <row>
10954 <entry role="func_table_entry"><para role="func_signature">
10955 <indexterm>
10956 <primary>enum_last</primary>
10957 </indexterm>
10958 <function>enum_last</function> ( <type>anyenum</type> )
10959 <returnvalue>anyenum</returnvalue>
10960 </para>
10961 <para>
10962 Returns the last value of the input enum type.
10963 </para>
10964 <para>
10965 <literal>enum_last(null::rainbow)</literal>
10966 <returnvalue>purple</returnvalue>
10967 </para></entry>
10968 </row>
10969 <row>
10970 <entry role="func_table_entry"><para role="func_signature">
10971 <indexterm>
10972 <primary>enum_range</primary>
10973 </indexterm>
10974 <function>enum_range</function> ( <type>anyenum</type> )
10975 <returnvalue>anyarray</returnvalue>
10976 </para>
10977 <para>
10978 Returns all values of the input enum type in an ordered array.
10979 </para>
10980 <para>
10981 <literal>enum_range(null::rainbow)</literal>
10982 <returnvalue>{red,orange,yellow,&zwsp;green,blue,purple}</returnvalue>
10983 </para></entry>
10984 </row>
10985 <row>
10986 <entry role="func_table_entry"><para role="func_signature">
10987 <function>enum_range</function> ( <type>anyenum</type>, <type>anyenum</type> )
10988 <returnvalue>anyarray</returnvalue>
10989 </para>
10990 <para>
10991 Returns the range between the two given enum values, as an ordered
10992 array. The values must be from the same enum type. If the first
10993 parameter is null, the result will start with the first value of
10994 the enum type.
10995 If the second parameter is null, the result will end with the last
10996 value of the enum type.
10997 </para>
10998 <para>
10999 <literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal>
11000 <returnvalue>{orange,yellow,green}</returnvalue>
11001 </para>
11002 <para>
11003 <literal>enum_range(NULL, 'green'::rainbow)</literal>
11004 <returnvalue>{red,orange,&zwsp;yellow,green}</returnvalue>
11005 </para>
11006 <para>
11007 <literal>enum_range('orange'::rainbow, NULL)</literal>
11008 <returnvalue>{orange,yellow,green,&zwsp;blue,purple}</returnvalue>
11009 </para></entry>
11010 </row>
11011 </tbody>
11012 </tgroup>
11013 </table>
11015 <para>
11016 Notice that except for the two-argument form of <function>enum_range</function>,
11017 these functions disregard the specific value passed to them; they care
11018 only about its declared data type. Either null or a specific value of
11019 the type can be passed, with the same result. It is more common to
11020 apply these functions to a table column or function argument than to
11021 a hardwired type name as used in the examples.
11022 </para>
11023 </sect1>
11025 <sect1 id="functions-geometry">
11026 <title>Geometric Functions and Operators</title>
11028 <para>
11029 The geometric types <type>point</type>, <type>box</type>,
11030 <type>lseg</type>, <type>line</type>, <type>path</type>,
11031 <type>polygon</type>, and <type>circle</type> have a large set of
11032 native support functions and operators, shown in <xref
11033 linkend="functions-geometry-op-table"/>, <xref
11034 linkend="functions-geometry-func-table"/>, and <xref
11035 linkend="functions-geometry-conv-table"/>.
11036 </para>
11038 <table id="functions-geometry-op-table">
11039 <title>Geometric Operators</title>
11040 <tgroup cols="1">
11041 <thead>
11042 <row>
11043 <entry role="func_table_entry"><para role="func_signature">
11044 Operator
11045 </para>
11046 <para>
11047 Description
11048 </para>
11049 <para>
11050 Example(s)
11051 </para></entry>
11052 </row>
11053 </thead>
11055 <tbody>
11056 <row>
11057 <entry role="func_table_entry"><para role="func_signature">
11058 <replaceable>geometric_type</replaceable> <literal>+</literal> <type>point</type>
11059 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11060 </para>
11061 <para>
11062 Adds the coordinates of the second <type>point</type> to those of each
11063 point of the first argument, thus performing translation.
11064 Available for <type>point</type>, <type>box</type>, <type>path</type>,
11065 <type>circle</type>.
11066 </para>
11067 <para>
11068 <literal>box '(1,1),(0,0)' + point '(2,0)'</literal>
11069 <returnvalue>(3,1),(2,0)</returnvalue>
11070 </para></entry>
11071 </row>
11073 <row>
11074 <entry role="func_table_entry"><para role="func_signature">
11075 <type>path</type> <literal>+</literal> <type>path</type>
11076 <returnvalue>path</returnvalue>
11077 </para>
11078 <para>
11079 Concatenates two open paths (returns NULL if either path is closed).
11080 </para>
11081 <para>
11082 <literal>path '[(0,0),(1,1)]' + path '[(2,2),(3,3),(4,4)]'</literal>
11083 <returnvalue>[(0,0),(1,1),(2,2),(3,3),(4,4)]</returnvalue>
11084 </para></entry>
11085 </row>
11087 <row>
11088 <entry role="func_table_entry"><para role="func_signature">
11089 <replaceable>geometric_type</replaceable> <literal>-</literal> <type>point</type>
11090 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11091 </para>
11092 <para>
11093 Subtracts the coordinates of the second <type>point</type> from those
11094 of each point of the first argument, thus performing translation.
11095 Available for <type>point</type>, <type>box</type>, <type>path</type>,
11096 <type>circle</type>.
11097 </para>
11098 <para>
11099 <literal>box '(1,1),(0,0)' - point '(2,0)'</literal>
11100 <returnvalue>(-1,1),(-2,0)</returnvalue>
11101 </para></entry>
11102 </row>
11104 <row>
11105 <entry role="func_table_entry"><para role="func_signature">
11106 <replaceable>geometric_type</replaceable> <literal>*</literal> <type>point</type>
11107 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11108 </para>
11109 <para>
11110 Multiplies each point of the first argument by the second
11111 <type>point</type> (treating a point as being a complex number
11112 represented by real and imaginary parts, and performing standard
11113 complex multiplication). If one interprets
11114 the second <type>point</type> as a vector, this is equivalent to
11115 scaling the object's size and distance from the origin by the length
11116 of the vector, and rotating it counterclockwise around the origin by
11117 the vector's angle from the <replaceable>x</replaceable> axis.
11118 Available for <type>point</type>, <type>box</type>,<footnote
11119 id="functions-geometry-rotation-fn"><para><quote>Rotating</quote> a
11120 box with these operators only moves its corner points: the box is
11121 still considered to have sides parallel to the axes. Hence the box's
11122 size is not preserved, as a true rotation would do.</para></footnote>
11123 <type>path</type>, <type>circle</type>.
11124 </para>
11125 <para>
11126 <literal>path '((0,0),(1,0),(1,1))' * point '(3.0,0)'</literal>
11127 <returnvalue>((0,0),(3,0),(3,3))</returnvalue>
11128 </para>
11129 <para>
11130 <literal>path '((0,0),(1,0),(1,1))' * point(cosd(45), sind(45))</literal>
11131 <returnvalue>((0,0),&zwsp;(0.7071067811865475,0.7071067811865475),&zwsp;(0,1.414213562373095))</returnvalue>
11132 </para></entry>
11133 </row>
11135 <row>
11136 <entry role="func_table_entry"><para role="func_signature">
11137 <replaceable>geometric_type</replaceable> <literal>/</literal> <type>point</type>
11138 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11139 </para>
11140 <para>
11141 Divides each point of the first argument by the second
11142 <type>point</type> (treating a point as being a complex number
11143 represented by real and imaginary parts, and performing standard
11144 complex division). If one interprets
11145 the second <type>point</type> as a vector, this is equivalent to
11146 scaling the object's size and distance from the origin down by the
11147 length of the vector, and rotating it clockwise around the origin by
11148 the vector's angle from the <replaceable>x</replaceable> axis.
11149 Available for <type>point</type>, <type>box</type>,<footnoteref
11150 linkend="functions-geometry-rotation-fn"/> <type>path</type>,
11151 <type>circle</type>.
11152 </para>
11153 <para>
11154 <literal>path '((0,0),(1,0),(1,1))' / point '(2.0,0)'</literal>
11155 <returnvalue>((0,0),(0.5,0),(0.5,0.5))</returnvalue>
11156 </para>
11157 <para>
11158 <literal>path '((0,0),(1,0),(1,1))' / point(cosd(45), sind(45))</literal>
11159 <returnvalue>((0,0),&zwsp;(0.7071067811865476,-0.7071067811865476),&zwsp;(1.4142135623730951,0))</returnvalue>
11160 </para></entry>
11161 </row>
11163 <row>
11164 <entry role="func_table_entry"><para role="func_signature">
11165 <literal>@-@</literal> <replaceable>geometric_type</replaceable>
11166 <returnvalue>double precision</returnvalue>
11167 </para>
11168 <para>
11169 Computes the total length.
11170 Available for <type>lseg</type>, <type>path</type>.
11171 </para>
11172 <para>
11173 <literal>@-@ path '[(0,0),(1,0),(1,1)]'</literal>
11174 <returnvalue>2</returnvalue>
11175 </para></entry>
11176 </row>
11178 <row>
11179 <entry role="func_table_entry"><para role="func_signature">
11180 <literal>@@</literal> <replaceable>geometric_type</replaceable>
11181 <returnvalue>point</returnvalue>
11182 </para>
11183 <para>
11184 Computes the center point.
11185 Available for <type>box</type>, <type>lseg</type>,
11186 <type>polygon</type>, <type>circle</type>.
11187 </para>
11188 <para>
11189 <literal>@@ box '(2,2),(0,0)'</literal>
11190 <returnvalue>(1,1)</returnvalue>
11191 </para></entry>
11192 </row>
11194 <row>
11195 <entry role="func_table_entry"><para role="func_signature">
11196 <literal>#</literal> <replaceable>geometric_type</replaceable>
11197 <returnvalue>integer</returnvalue>
11198 </para>
11199 <para>
11200 Returns the number of points.
11201 Available for <type>path</type>, <type>polygon</type>.
11202 </para>
11203 <para>
11204 <literal># path '((1,0),(0,1),(-1,0))'</literal>
11205 <returnvalue>3</returnvalue>
11206 </para></entry>
11207 </row>
11209 <row>
11210 <entry role="func_table_entry"><para role="func_signature">
11211 <replaceable>geometric_type</replaceable> <literal>#</literal> <replaceable>geometric_type</replaceable>
11212 <returnvalue>point</returnvalue>
11213 </para>
11214 <para>
11215 Computes the point of intersection, or NULL if there is none.
11216 Available for <type>lseg</type>, <type>line</type>.
11217 </para>
11218 <para>
11219 <literal>lseg '[(0,0),(1,1)]' # lseg '[(1,0),(0,1)]'</literal>
11220 <returnvalue>(0.5,0.5)</returnvalue>
11221 </para></entry>
11222 </row>
11224 <row>
11225 <entry role="func_table_entry"><para role="func_signature">
11226 <type>box</type> <literal>#</literal> <type>box</type>
11227 <returnvalue>box</returnvalue>
11228 </para>
11229 <para>
11230 Computes the intersection of two boxes, or NULL if there is none.
11231 </para>
11232 <para>
11233 <literal>box '(2,2),(-1,-1)' # box '(1,1),(-2,-2)'</literal>
11234 <returnvalue>(1,1),(-1,-1)</returnvalue>
11235 </para></entry>
11236 </row>
11238 <row>
11239 <entry role="func_table_entry"><para role="func_signature">
11240 <replaceable>geometric_type</replaceable> <literal>##</literal> <replaceable>geometric_type</replaceable>
11241 <returnvalue>point</returnvalue>
11242 </para>
11243 <para>
11244 Computes the closest point to the first object on the second object.
11245 Available for these pairs of types:
11246 (<type>point</type>, <type>box</type>),
11247 (<type>point</type>, <type>lseg</type>),
11248 (<type>point</type>, <type>line</type>),
11249 (<type>lseg</type>, <type>box</type>),
11250 (<type>lseg</type>, <type>lseg</type>),
11251 (<type>line</type>, <type>lseg</type>).
11252 </para>
11253 <para>
11254 <literal>point '(0,0)' ## lseg '[(2,0),(0,2)]'</literal>
11255 <returnvalue>(1,1)</returnvalue>
11256 </para></entry>
11257 </row>
11259 <row>
11260 <entry role="func_table_entry"><para role="func_signature">
11261 <replaceable>geometric_type</replaceable> <literal>&lt;-&gt;</literal> <replaceable>geometric_type</replaceable>
11262 <returnvalue>double precision</returnvalue>
11263 </para>
11264 <para>
11265 Computes the distance between the objects.
11266 Available for all seven geometric types, for all combinations
11267 of <type>point</type> with another geometric type, and for
11268 these additional pairs of types:
11269 (<type>box</type>, <type>lseg</type>),
11270 (<type>lseg</type>, <type>line</type>),
11271 (<type>polygon</type>, <type>circle</type>)
11272 (and the commutator cases).
11273 </para>
11274 <para>
11275 <literal>circle '&lt;(0,0),1&gt;' &lt;-&gt; circle '&lt;(5,0),1&gt;'</literal>
11276 <returnvalue>3</returnvalue>
11277 </para></entry>
11278 </row>
11280 <row>
11281 <entry role="func_table_entry"><para role="func_signature">
11282 <replaceable>geometric_type</replaceable> <literal>@&gt;</literal> <replaceable>geometric_type</replaceable>
11283 <returnvalue>boolean</returnvalue>
11284 </para>
11285 <para>
11286 Does first object contain second?
11287 Available for these pairs of types:
11288 (<literal>box</literal>, <literal>point</literal>),
11289 (<literal>box</literal>, <literal>box</literal>),
11290 (<literal>path</literal>, <literal>point</literal>),
11291 (<literal>polygon</literal>, <literal>point</literal>),
11292 (<literal>polygon</literal>, <literal>polygon</literal>),
11293 (<literal>circle</literal>, <literal>point</literal>),
11294 (<literal>circle</literal>, <literal>circle</literal>).
11295 </para>
11296 <para>
11297 <literal>circle '&lt;(0,0),2&gt;' @&gt; point '(1,1)'</literal>
11298 <returnvalue>t</returnvalue>
11299 </para></entry>
11300 </row>
11302 <row>
11303 <entry role="func_table_entry"><para role="func_signature">
11304 <replaceable>geometric_type</replaceable> <literal>&lt;@</literal> <replaceable>geometric_type</replaceable>
11305 <returnvalue>boolean</returnvalue>
11306 </para>
11307 <para>
11308 Is first object contained in or on second?
11309 Available for these pairs of types:
11310 (<literal>point</literal>, <literal>box</literal>),
11311 (<literal>point</literal>, <literal>lseg</literal>),
11312 (<literal>point</literal>, <literal>line</literal>),
11313 (<literal>point</literal>, <literal>path</literal>),
11314 (<literal>point</literal>, <literal>polygon</literal>),
11315 (<literal>point</literal>, <literal>circle</literal>),
11316 (<literal>box</literal>, <literal>box</literal>),
11317 (<literal>lseg</literal>, <literal>box</literal>),
11318 (<literal>lseg</literal>, <literal>line</literal>),
11319 (<literal>polygon</literal>, <literal>polygon</literal>),
11320 (<literal>circle</literal>, <literal>circle</literal>).
11321 </para>
11322 <para>
11323 <literal>point '(1,1)' &lt;@ circle '&lt;(0,0),2&gt;'</literal>
11324 <returnvalue>t</returnvalue>
11325 </para></entry>
11326 </row>
11328 <row>
11329 <entry role="func_table_entry"><para role="func_signature">
11330 <replaceable>geometric_type</replaceable> <literal>&amp;&amp;</literal> <replaceable>geometric_type</replaceable>
11331 <returnvalue>boolean</returnvalue>
11332 </para>
11333 <para>
11334 Do these objects overlap? (One point in common makes this true.)
11335 Available for <type>box</type>, <type>polygon</type>,
11336 <type>circle</type>.
11337 </para>
11338 <para>
11339 <literal>box '(1,1),(0,0)' &amp;&amp; box '(2,2),(0,0)'</literal>
11340 <returnvalue>t</returnvalue>
11341 </para></entry>
11342 </row>
11344 <row>
11345 <entry role="func_table_entry"><para role="func_signature">
11346 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;</literal> <replaceable>geometric_type</replaceable>
11347 <returnvalue>boolean</returnvalue>
11348 </para>
11349 <para>
11350 Is first object strictly left of second?
11351 Available for <type>point</type>, <type>box</type>,
11352 <type>polygon</type>, <type>circle</type>.
11353 </para>
11354 <para>
11355 <literal>circle '&lt;(0,0),1&gt;' &lt;&lt; circle '&lt;(5,0),1&gt;'</literal>
11356 <returnvalue>t</returnvalue>
11357 </para></entry>
11358 </row>
11360 <row>
11361 <entry role="func_table_entry"><para role="func_signature">
11362 <replaceable>geometric_type</replaceable> <literal>&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11363 <returnvalue>boolean</returnvalue>
11364 </para>
11365 <para>
11366 Is first object strictly right of second?
11367 Available for <type>point</type>, <type>box</type>,
11368 <type>polygon</type>, <type>circle</type>.
11369 </para>
11370 <para>
11371 <literal>circle '&lt;(5,0),1&gt;' &gt;&gt; circle '&lt;(0,0),1&gt;'</literal>
11372 <returnvalue>t</returnvalue>
11373 </para></entry>
11374 </row>
11376 <row>
11377 <entry role="func_table_entry"><para role="func_signature">
11378 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;</literal> <replaceable>geometric_type</replaceable>
11379 <returnvalue>boolean</returnvalue>
11380 </para>
11381 <para>
11382 Does first object not extend to the right of second?
11383 Available for <type>box</type>, <type>polygon</type>,
11384 <type>circle</type>.
11385 </para>
11386 <para>
11387 <literal>box '(1,1),(0,0)' &amp;&lt; box '(2,2),(0,0)'</literal>
11388 <returnvalue>t</returnvalue>
11389 </para></entry>
11390 </row>
11392 <row>
11393 <entry role="func_table_entry"><para role="func_signature">
11394 <replaceable>geometric_type</replaceable> <literal>&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11395 <returnvalue>boolean</returnvalue>
11396 </para>
11397 <para>
11398 Does first object not extend to the left of second?
11399 Available for <type>box</type>, <type>polygon</type>,
11400 <type>circle</type>.
11401 </para>
11402 <para>
11403 <literal>box '(3,3),(0,0)' &amp;&gt; box '(2,2),(0,0)'</literal>
11404 <returnvalue>t</returnvalue>
11405 </para></entry>
11406 </row>
11408 <row>
11409 <entry role="func_table_entry"><para role="func_signature">
11410 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;|</literal> <replaceable>geometric_type</replaceable>
11411 <returnvalue>boolean</returnvalue>
11412 </para>
11413 <para>
11414 Is first object strictly below second?
11415 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11416 <type>circle</type>.
11417 </para>
11418 <para>
11419 <literal>box '(3,3),(0,0)' &lt;&lt;| box '(5,5),(3,4)'</literal>
11420 <returnvalue>t</returnvalue>
11421 </para></entry>
11422 </row>
11424 <row>
11425 <entry role="func_table_entry"><para role="func_signature">
11426 <replaceable>geometric_type</replaceable> <literal>|&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11427 <returnvalue>boolean</returnvalue>
11428 </para>
11429 <para>
11430 Is first object strictly above second?
11431 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11432 <type>circle</type>.
11433 </para>
11434 <para>
11435 <literal>box '(5,5),(3,4)' |&gt;&gt; box '(3,3),(0,0)'</literal>
11436 <returnvalue>t</returnvalue>
11437 </para></entry>
11438 </row>
11440 <row>
11441 <entry role="func_table_entry"><para role="func_signature">
11442 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;|</literal> <replaceable>geometric_type</replaceable>
11443 <returnvalue>boolean</returnvalue>
11444 </para>
11445 <para>
11446 Does first object not extend above second?
11447 Available for <type>box</type>, <type>polygon</type>,
11448 <type>circle</type>.
11449 </para>
11450 <para>
11451 <literal>box '(1,1),(0,0)' &amp;&lt;| box '(2,2),(0,0)'</literal>
11452 <returnvalue>t</returnvalue>
11453 </para></entry>
11454 </row>
11456 <row>
11457 <entry role="func_table_entry"><para role="func_signature">
11458 <replaceable>geometric_type</replaceable> <literal>|&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11459 <returnvalue>boolean</returnvalue>
11460 </para>
11461 <para>
11462 Does first object not extend below second?
11463 Available for <type>box</type>, <type>polygon</type>,
11464 <type>circle</type>.
11465 </para>
11466 <para>
11467 <literal>box '(3,3),(0,0)' |&amp;&gt; box '(2,2),(0,0)'</literal>
11468 <returnvalue>t</returnvalue>
11469 </para></entry>
11470 </row>
11472 <row>
11473 <entry role="func_table_entry"><para role="func_signature">
11474 <type>box</type> <literal>&lt;^</literal> <type>box</type>
11475 <returnvalue>boolean</returnvalue>
11476 </para>
11477 <para>
11478 Is first object below second (allows edges to touch)?
11479 </para>
11480 <para>
11481 <literal>box '((1,1),(0,0))' &lt;^ box '((2,2),(1,1))'</literal>
11482 <returnvalue>t</returnvalue>
11483 </para></entry>
11484 </row>
11486 <row>
11487 <entry role="func_table_entry"><para role="func_signature">
11488 <type>box</type> <literal>&gt;^</literal> <type>box</type>
11489 <returnvalue>boolean</returnvalue>
11490 </para>
11491 <para>
11492 Is first object above second (allows edges to touch)?
11493 </para>
11494 <para>
11495 <literal>box '((2,2),(1,1))' &gt;^ box '((1,1),(0,0))'</literal>
11496 <returnvalue>t</returnvalue>
11497 </para></entry>
11498 </row>
11500 <row>
11501 <entry role="func_table_entry"><para role="func_signature">
11502 <replaceable>geometric_type</replaceable> <literal>?#</literal> <replaceable>geometric_type</replaceable>
11503 <returnvalue>boolean</returnvalue>
11504 </para>
11505 <para>
11506 Do these objects intersect?
11507 Available for these pairs of types:
11508 (<type>box</type>, <type>box</type>),
11509 (<type>lseg</type>, <type>box</type>),
11510 (<type>lseg</type>, <type>lseg</type>),
11511 (<type>lseg</type>, <type>line</type>),
11512 (<type>line</type>, <type>box</type>),
11513 (<type>line</type>, <type>line</type>),
11514 (<type>path</type>, <type>path</type>).
11515 </para>
11516 <para>
11517 <literal>lseg '[(-1,0),(1,0)]' ?# box '(2,2),(-2,-2)'</literal>
11518 <returnvalue>t</returnvalue>
11519 </para></entry>
11520 </row>
11522 <row>
11523 <entry role="func_table_entry"><para role="func_signature">
11524 <literal>?-</literal> <type>line</type>
11525 <returnvalue>boolean</returnvalue>
11526 </para>
11527 <para role="func_signature">
11528 <literal>?-</literal> <type>lseg</type>
11529 <returnvalue>boolean</returnvalue>
11530 </para>
11531 <para>
11532 Is line horizontal?
11533 </para>
11534 <para>
11535 <literal>?- lseg '[(-1,0),(1,0)]'</literal>
11536 <returnvalue>t</returnvalue>
11537 </para></entry>
11538 </row>
11540 <row>
11541 <entry role="func_table_entry"><para role="func_signature">
11542 <type>point</type> <literal>?-</literal> <type>point</type>
11543 <returnvalue>boolean</returnvalue>
11544 </para>
11545 <para>
11546 Are points horizontally aligned (that is, have same y coordinate)?
11547 </para>
11548 <para>
11549 <literal>point '(1,0)' ?- point '(0,0)'</literal>
11550 <returnvalue>t</returnvalue>
11551 </para></entry>
11552 </row>
11554 <row>
11555 <entry role="func_table_entry"><para role="func_signature">
11556 <literal>?|</literal> <type>line</type>
11557 <returnvalue>boolean</returnvalue>
11558 </para>
11559 <para role="func_signature">
11560 <literal>?|</literal> <type>lseg</type>
11561 <returnvalue>boolean</returnvalue>
11562 </para>
11563 <para>
11564 Is line vertical?
11565 </para>
11566 <para>
11567 <literal>?| lseg '[(-1,0),(1,0)]'</literal>
11568 <returnvalue>f</returnvalue>
11569 </para></entry>
11570 </row>
11572 <row>
11573 <entry role="func_table_entry"><para role="func_signature">
11574 <type>point</type> <literal>?|</literal> <type>point</type>
11575 <returnvalue>boolean</returnvalue>
11576 </para>
11577 <para>
11578 Are points vertically aligned (that is, have same x coordinate)?
11579 </para>
11580 <para>
11581 <literal>point '(0,1)' ?| point '(0,0)'</literal>
11582 <returnvalue>t</returnvalue>
11583 </para></entry>
11584 </row>
11586 <row>
11587 <entry role="func_table_entry"><para role="func_signature">
11588 <type>line</type> <literal>?-|</literal> <type>line</type>
11589 <returnvalue>boolean</returnvalue>
11590 </para>
11591 <para role="func_signature">
11592 <type>lseg</type> <literal>?-|</literal> <type>lseg</type>
11593 <returnvalue>boolean</returnvalue>
11594 </para>
11595 <para>
11596 Are lines perpendicular?
11597 </para>
11598 <para>
11599 <literal>lseg '[(0,0),(0,1)]' ?-| lseg '[(0,0),(1,0)]'</literal>
11600 <returnvalue>t</returnvalue>
11601 </para></entry>
11602 </row>
11604 <row>
11605 <entry role="func_table_entry"><para role="func_signature">
11606 <type>line</type> <literal>?||</literal> <type>line</type>
11607 <returnvalue>boolean</returnvalue>
11608 </para>
11609 <para role="func_signature">
11610 <type>lseg</type> <literal>?||</literal> <type>lseg</type>
11611 <returnvalue>boolean</returnvalue>
11612 </para>
11613 <para>
11614 Are lines parallel?
11615 </para>
11616 <para>
11617 <literal>lseg '[(-1,0),(1,0)]' ?|| lseg '[(-1,2),(1,2)]'</literal>
11618 <returnvalue>t</returnvalue>
11619 </para></entry>
11620 </row>
11622 <row>
11623 <entry role="func_table_entry"><para role="func_signature">
11624 <replaceable>geometric_type</replaceable> <literal>~=</literal> <replaceable>geometric_type</replaceable>
11625 <returnvalue>boolean</returnvalue>
11626 </para>
11627 <para>
11628 Are these objects the same?
11629 Available for <type>point</type>, <type>box</type>,
11630 <type>polygon</type>, <type>circle</type>.
11631 </para>
11632 <para>
11633 <literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal>
11634 <returnvalue>t</returnvalue>
11635 </para></entry>
11636 </row>
11637 </tbody>
11638 </tgroup>
11639 </table>
11641 <caution>
11642 <para>
11643 Note that the <quote>same as</quote> operator, <literal>~=</literal>,
11644 represents the usual notion of equality for the <type>point</type>,
11645 <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
11646 Some of the geometric types also have an <literal>=</literal> operator, but
11647 <literal>=</literal> compares for equal <emphasis>areas</emphasis> only.
11648 The other scalar comparison operators (<literal>&lt;=</literal> and so
11649 on), where available for these types, likewise compare areas.
11650 </para>
11651 </caution>
11653 <note>
11654 <para>
11655 Before <productname>PostgreSQL</productname> 14, the point
11656 is strictly below/above comparison operators <type>point</type>
11657 <literal>&lt;&lt;|</literal> <type>point</type> and <type>point</type>
11658 <literal>|&gt;&gt;</literal> <type>point</type> were respectively
11659 called <literal>&lt;^</literal> and <literal>&gt;^</literal>. These
11660 names are still available, but are deprecated and will eventually be
11661 removed.
11662 </para>
11663 </note>
11665 <table id="functions-geometry-func-table">
11666 <title>Geometric Functions</title>
11667 <tgroup cols="1">
11668 <thead>
11669 <row>
11670 <entry role="func_table_entry"><para role="func_signature">
11671 Function
11672 </para>
11673 <para>
11674 Description
11675 </para>
11676 <para>
11677 Example(s)
11678 </para></entry>
11679 </row>
11680 </thead>
11682 <tbody>
11683 <row>
11684 <entry role="func_table_entry"><para role="func_signature">
11685 <indexterm>
11686 <primary>area</primary>
11687 </indexterm>
11688 <function>area</function> ( <replaceable>geometric_type</replaceable> )
11689 <returnvalue>double precision</returnvalue>
11690 </para>
11691 <para>
11692 Computes area.
11693 Available for <type>box</type>, <type>path</type>, <type>circle</type>.
11694 A <type>path</type> input must be closed, else NULL is returned.
11695 Also, if the <type>path</type> is self-intersecting, the result may be
11696 meaningless.
11697 </para>
11698 <para>
11699 <literal>area(box '(2,2),(0,0)')</literal>
11700 <returnvalue>4</returnvalue>
11701 </para></entry>
11702 </row>
11704 <row>
11705 <entry role="func_table_entry"><para role="func_signature">
11706 <indexterm>
11707 <primary>center</primary>
11708 </indexterm>
11709 <function>center</function> ( <replaceable>geometric_type</replaceable> )
11710 <returnvalue>point</returnvalue>
11711 </para>
11712 <para>
11713 Computes center point.
11714 Available for <type>box</type>, <type>circle</type>.
11715 </para>
11716 <para>
11717 <literal>center(box '(1,2),(0,0)')</literal>
11718 <returnvalue>(0.5,1)</returnvalue>
11719 </para></entry>
11720 </row>
11722 <row>
11723 <entry role="func_table_entry"><para role="func_signature">
11724 <indexterm>
11725 <primary>diagonal</primary>
11726 </indexterm>
11727 <function>diagonal</function> ( <type>box</type> )
11728 <returnvalue>lseg</returnvalue>
11729 </para>
11730 <para>
11731 Extracts box's diagonal as a line segment
11732 (same as <function>lseg(box)</function>).
11733 </para>
11734 <para>
11735 <literal>diagonal(box '(1,2),(0,0)')</literal>
11736 <returnvalue>[(1,2),(0,0)]</returnvalue>
11737 </para></entry>
11738 </row>
11740 <row>
11741 <entry role="func_table_entry"><para role="func_signature">
11742 <indexterm>
11743 <primary>diameter</primary>
11744 </indexterm>
11745 <function>diameter</function> ( <type>circle</type> )
11746 <returnvalue>double precision</returnvalue>
11747 </para>
11748 <para>
11749 Computes diameter of circle.
11750 </para>
11751 <para>
11752 <literal>diameter(circle '&lt;(0,0),2&gt;')</literal>
11753 <returnvalue>4</returnvalue>
11754 </para></entry>
11755 </row>
11757 <row>
11758 <entry role="func_table_entry"><para role="func_signature">
11759 <indexterm>
11760 <primary>height</primary>
11761 </indexterm>
11762 <function>height</function> ( <type>box</type> )
11763 <returnvalue>double precision</returnvalue>
11764 </para>
11765 <para>
11766 Computes vertical size of box.
11767 </para>
11768 <para>
11769 <literal>height(box '(1,2),(0,0)')</literal>
11770 <returnvalue>2</returnvalue>
11771 </para></entry>
11772 </row>
11774 <row>
11775 <entry role="func_table_entry"><para role="func_signature">
11776 <indexterm>
11777 <primary>isclosed</primary>
11778 </indexterm>
11779 <function>isclosed</function> ( <type>path</type> )
11780 <returnvalue>boolean</returnvalue>
11781 </para>
11782 <para>
11783 Is path closed?
11784 </para>
11785 <para>
11786 <literal>isclosed(path '((0,0),(1,1),(2,0))')</literal>
11787 <returnvalue>t</returnvalue>
11788 </para></entry>
11789 </row>
11791 <row>
11792 <entry role="func_table_entry"><para role="func_signature">
11793 <indexterm>
11794 <primary>isopen</primary>
11795 </indexterm>
11796 <function>isopen</function> ( <type>path</type> )
11797 <returnvalue>boolean</returnvalue>
11798 </para>
11799 <para>
11800 Is path open?
11801 </para>
11802 <para>
11803 <literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal>
11804 <returnvalue>t</returnvalue>
11805 </para></entry>
11806 </row>
11808 <row>
11809 <entry role="func_table_entry"><para role="func_signature">
11810 <indexterm>
11811 <primary>length</primary>
11812 </indexterm>
11813 <function>length</function> ( <replaceable>geometric_type</replaceable> )
11814 <returnvalue>double precision</returnvalue>
11815 </para>
11816 <para>
11817 Computes the total length.
11818 Available for <type>lseg</type>, <type>path</type>.
11819 </para>
11820 <para>
11821 <literal>length(path '((-1,0),(1,0))')</literal>
11822 <returnvalue>4</returnvalue>
11823 </para></entry>
11824 </row>
11826 <row>
11827 <entry role="func_table_entry"><para role="func_signature">
11828 <indexterm>
11829 <primary>npoints</primary>
11830 </indexterm>
11831 <function>npoints</function> ( <replaceable>geometric_type</replaceable> )
11832 <returnvalue>integer</returnvalue>
11833 </para>
11834 <para>
11835 Returns the number of points.
11836 Available for <type>path</type>, <type>polygon</type>.
11837 </para>
11838 <para>
11839 <literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal>
11840 <returnvalue>3</returnvalue>
11841 </para></entry>
11842 </row>
11844 <row>
11845 <entry role="func_table_entry"><para role="func_signature">
11846 <indexterm>
11847 <primary>pclose</primary>
11848 </indexterm>
11849 <function>pclose</function> ( <type>path</type> )
11850 <returnvalue>path</returnvalue>
11851 </para>
11852 <para>
11853 Converts path to closed form.
11854 </para>
11855 <para>
11856 <literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal>
11857 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
11858 </para></entry>
11859 </row>
11861 <row>
11862 <entry role="func_table_entry"><para role="func_signature">
11863 <indexterm>
11864 <primary>popen</primary>
11865 </indexterm>
11866 <function>popen</function> ( <type>path</type> )
11867 <returnvalue>path</returnvalue>
11868 </para>
11869 <para>
11870 Converts path to open form.
11871 </para>
11872 <para>
11873 <literal>popen(path '((0,0),(1,1),(2,0))')</literal>
11874 <returnvalue>[(0,0),(1,1),(2,0)]</returnvalue>
11875 </para></entry>
11876 </row>
11878 <row>
11879 <entry role="func_table_entry"><para role="func_signature">
11880 <indexterm>
11881 <primary>radius</primary>
11882 </indexterm>
11883 <function>radius</function> ( <type>circle</type> )
11884 <returnvalue>double precision</returnvalue>
11885 </para>
11886 <para>
11887 Computes radius of circle.
11888 </para>
11889 <para>
11890 <literal>radius(circle '&lt;(0,0),2&gt;')</literal>
11891 <returnvalue>2</returnvalue>
11892 </para></entry>
11893 </row>
11895 <row>
11896 <entry role="func_table_entry"><para role="func_signature">
11897 <indexterm>
11898 <primary>slope</primary>
11899 </indexterm>
11900 <function>slope</function> ( <type>point</type>, <type>point</type> )
11901 <returnvalue>double precision</returnvalue>
11902 </para>
11903 <para>
11904 Computes slope of a line drawn through the two points.
11905 </para>
11906 <para>
11907 <literal>slope(point '(0,0)', point '(2,1)')</literal>
11908 <returnvalue>0.5</returnvalue>
11909 </para></entry>
11910 </row>
11912 <row>
11913 <entry role="func_table_entry"><para role="func_signature">
11914 <indexterm>
11915 <primary>width</primary>
11916 </indexterm>
11917 <function>width</function> ( <type>box</type> )
11918 <returnvalue>double precision</returnvalue>
11919 </para>
11920 <para>
11921 Computes horizontal size of box.
11922 </para>
11923 <para>
11924 <literal>width(box '(1,2),(0,0)')</literal>
11925 <returnvalue>1</returnvalue>
11926 </para></entry>
11927 </row>
11928 </tbody>
11929 </tgroup>
11930 </table>
11932 <table id="functions-geometry-conv-table">
11933 <title>Geometric Type Conversion Functions</title>
11934 <tgroup cols="1">
11935 <thead>
11936 <row>
11937 <entry role="func_table_entry"><para role="func_signature">
11938 Function
11939 </para>
11940 <para>
11941 Description
11942 </para>
11943 <para>
11944 Example(s)
11945 </para></entry>
11946 </row>
11947 </thead>
11948 <tbody>
11950 <row>
11951 <entry role="func_table_entry"><para role="func_signature">
11952 <indexterm>
11953 <primary>box</primary>
11954 </indexterm>
11955 <function>box</function> ( <type>circle</type> )
11956 <returnvalue>box</returnvalue>
11957 </para>
11958 <para>
11959 Computes box inscribed within the circle.
11960 </para>
11961 <para>
11962 <literal>box(circle '&lt;(0,0),2&gt;')</literal>
11963 <returnvalue>(1.414213562373095,1.414213562373095),&zwsp;(-1.414213562373095,-1.414213562373095)</returnvalue>
11964 </para></entry>
11965 </row>
11967 <row>
11968 <entry role="func_table_entry"><para role="func_signature">
11969 <function>box</function> ( <type>point</type> )
11970 <returnvalue>box</returnvalue>
11971 </para>
11972 <para>
11973 Converts point to empty box.
11974 </para>
11975 <para>
11976 <literal>box(point '(1,0)')</literal>
11977 <returnvalue>(1,0),(1,0)</returnvalue>
11978 </para></entry>
11979 </row>
11981 <row>
11982 <entry role="func_table_entry"><para role="func_signature">
11983 <function>box</function> ( <type>point</type>, <type>point</type> )
11984 <returnvalue>box</returnvalue>
11985 </para>
11986 <para>
11987 Converts any two corner points to box.
11988 </para>
11989 <para>
11990 <literal>box(point '(0,1)', point '(1,0)')</literal>
11991 <returnvalue>(1,1),(0,0)</returnvalue>
11992 </para></entry>
11993 </row>
11995 <row>
11996 <entry role="func_table_entry"><para role="func_signature">
11997 <function>box</function> ( <type>polygon</type> )
11998 <returnvalue>box</returnvalue>
11999 </para>
12000 <para>
12001 Computes bounding box of polygon.
12002 </para>
12003 <para>
12004 <literal>box(polygon '((0,0),(1,1),(2,0))')</literal>
12005 <returnvalue>(2,1),(0,0)</returnvalue>
12006 </para></entry>
12007 </row>
12009 <row>
12010 <entry role="func_table_entry"><para role="func_signature">
12011 <indexterm>
12012 <primary>bound_box</primary>
12013 </indexterm>
12014 <function>bound_box</function> ( <type>box</type>, <type>box</type> )
12015 <returnvalue>box</returnvalue>
12016 </para>
12017 <para>
12018 Computes bounding box of two boxes.
12019 </para>
12020 <para>
12021 <literal>bound_box(box '(1,1),(0,0)', box '(4,4),(3,3)')</literal>
12022 <returnvalue>(4,4),(0,0)</returnvalue>
12023 </para></entry>
12024 </row>
12026 <row>
12027 <entry role="func_table_entry"><para role="func_signature">
12028 <indexterm>
12029 <primary>circle</primary>
12030 </indexterm>
12031 <function>circle</function> ( <type>box</type> )
12032 <returnvalue>circle</returnvalue>
12033 </para>
12034 <para>
12035 Computes smallest circle enclosing box.
12036 </para>
12037 <para>
12038 <literal>circle(box '(1,1),(0,0)')</literal>
12039 <returnvalue>&lt;(0.5,0.5),0.7071067811865476&gt;</returnvalue>
12040 </para></entry>
12041 </row>
12043 <row>
12044 <entry role="func_table_entry"><para role="func_signature">
12045 <function>circle</function> ( <type>point</type>, <type>double precision</type> )
12046 <returnvalue>circle</returnvalue>
12047 </para>
12048 <para>
12049 Constructs circle from center and radius.
12050 </para>
12051 <para>
12052 <literal>circle(point '(0,0)', 2.0)</literal>
12053 <returnvalue>&lt;(0,0),2&gt;</returnvalue>
12054 </para></entry>
12055 </row>
12057 <row>
12058 <entry role="func_table_entry"><para role="func_signature">
12059 <function>circle</function> ( <type>polygon</type> )
12060 <returnvalue>circle</returnvalue>
12061 </para>
12062 <para>
12063 Converts polygon to circle. The circle's center is the mean of the
12064 positions of the polygon's points, and the radius is the average
12065 distance of the polygon's points from that center.
12066 </para>
12067 <para>
12068 <literal>circle(polygon '((0,0),(1,3),(2,0))')</literal>
12069 <returnvalue>&lt;(1,1),1.6094757082487299&gt;</returnvalue>
12070 </para></entry>
12071 </row>
12073 <row>
12074 <entry role="func_table_entry"><para role="func_signature">
12075 <indexterm>
12076 <primary>line</primary>
12077 </indexterm>
12078 <function>line</function> ( <type>point</type>, <type>point</type> )
12079 <returnvalue>line</returnvalue>
12080 </para>
12081 <para>
12082 Converts two points to the line through them.
12083 </para>
12084 <para>
12085 <literal>line(point '(-1,0)', point '(1,0)')</literal>
12086 <returnvalue>{0,-1,0}</returnvalue>
12087 </para></entry>
12088 </row>
12090 <row>
12091 <entry role="func_table_entry"><para role="func_signature">
12092 <indexterm>
12093 <primary>lseg</primary>
12094 </indexterm>
12095 <function>lseg</function> ( <type>box</type> )
12096 <returnvalue>lseg</returnvalue>
12097 </para>
12098 <para>
12099 Extracts box's diagonal as a line segment.
12100 </para>
12101 <para>
12102 <literal>lseg(box '(1,0),(-1,0)')</literal>
12103 <returnvalue>[(1,0),(-1,0)]</returnvalue>
12104 </para></entry>
12105 </row>
12107 <row>
12108 <entry role="func_table_entry"><para role="func_signature">
12109 <function>lseg</function> ( <type>point</type>, <type>point</type> )
12110 <returnvalue>lseg</returnvalue>
12111 </para>
12112 <para>
12113 Constructs line segment from two endpoints.
12114 </para>
12115 <para>
12116 <literal>lseg(point '(-1,0)', point '(1,0)')</literal>
12117 <returnvalue>[(-1,0),(1,0)]</returnvalue>
12118 </para></entry>
12119 </row>
12121 <row>
12122 <entry role="func_table_entry"><para role="func_signature">
12123 <indexterm>
12124 <primary>path</primary>
12125 </indexterm>
12126 <function>path</function> ( <type>polygon</type> )
12127 <returnvalue>path</returnvalue>
12128 </para>
12129 <para>
12130 Converts polygon to a closed path with the same list of points.
12131 </para>
12132 <para>
12133 <literal>path(polygon '((0,0),(1,1),(2,0))')</literal>
12134 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12135 </para></entry>
12136 </row>
12138 <row>
12139 <entry role="func_table_entry"><para role="func_signature">
12140 <indexterm>
12141 <primary>point</primary>
12142 </indexterm>
12143 <function>point</function> ( <type>double precision</type>, <type>double precision</type> )
12144 <returnvalue>point</returnvalue>
12145 </para>
12146 <para>
12147 Constructs point from its coordinates.
12148 </para>
12149 <para>
12150 <literal>point(23.4, -44.5)</literal>
12151 <returnvalue>(23.4,-44.5)</returnvalue>
12152 </para></entry>
12153 </row>
12155 <row>
12156 <entry role="func_table_entry"><para role="func_signature">
12157 <function>point</function> ( <type>box</type> )
12158 <returnvalue>point</returnvalue>
12159 </para>
12160 <para>
12161 Computes center of box.
12162 </para>
12163 <para>
12164 <literal>point(box '(1,0),(-1,0)')</literal>
12165 <returnvalue>(0,0)</returnvalue>
12166 </para></entry>
12167 </row>
12169 <row>
12170 <entry role="func_table_entry"><para role="func_signature">
12171 <function>point</function> ( <type>circle</type> )
12172 <returnvalue>point</returnvalue>
12173 </para>
12174 <para>
12175 Computes center of circle.
12176 </para>
12177 <para>
12178 <literal>point(circle '&lt;(0,0),2&gt;')</literal>
12179 <returnvalue>(0,0)</returnvalue>
12180 </para></entry>
12181 </row>
12183 <row>
12184 <entry role="func_table_entry"><para role="func_signature">
12185 <function>point</function> ( <type>lseg</type> )
12186 <returnvalue>point</returnvalue>
12187 </para>
12188 <para>
12189 Computes center of line segment.
12190 </para>
12191 <para>
12192 <literal>point(lseg '[(-1,0),(1,0)]')</literal>
12193 <returnvalue>(0,0)</returnvalue>
12194 </para></entry>
12195 </row>
12197 <row>
12198 <entry role="func_table_entry"><para role="func_signature">
12199 <function>point</function> ( <type>polygon</type> )
12200 <returnvalue>point</returnvalue>
12201 </para>
12202 <para>
12203 Computes center of polygon (the mean of the
12204 positions of the polygon's points).
12205 </para>
12206 <para>
12207 <literal>point(polygon '((0,0),(1,1),(2,0))')</literal>
12208 <returnvalue>(1,0.3333333333333333)</returnvalue>
12209 </para></entry>
12210 </row>
12212 <row>
12213 <entry role="func_table_entry"><para role="func_signature">
12214 <indexterm>
12215 <primary>polygon</primary>
12216 </indexterm>
12217 <function>polygon</function> ( <type>box</type> )
12218 <returnvalue>polygon</returnvalue>
12219 </para>
12220 <para>
12221 Converts box to a 4-point polygon.
12222 </para>
12223 <para>
12224 <literal>polygon(box '(1,1),(0,0)')</literal>
12225 <returnvalue>((0,0),(0,1),(1,1),(1,0))</returnvalue>
12226 </para></entry>
12227 </row>
12229 <row>
12230 <entry role="func_table_entry"><para role="func_signature">
12231 <function>polygon</function> ( <type>circle</type> )
12232 <returnvalue>polygon</returnvalue>
12233 </para>
12234 <para>
12235 Converts circle to a 12-point polygon.
12236 </para>
12237 <para>
12238 <literal>polygon(circle '&lt;(0,0),2&gt;')</literal>
12239 <returnvalue>((-2,0),&zwsp;(-1.7320508075688774,0.9999999999999999),&zwsp;(-1.0000000000000002,1.7320508075688772),&zwsp;(-1.2246063538223773e-16,2),&zwsp;(0.9999999999999996,1.7320508075688774),&zwsp;(1.732050807568877,1.0000000000000007),&zwsp;(2,2.4492127076447545e-16),&zwsp;(1.7320508075688776,-0.9999999999999994),&zwsp;(1.0000000000000009,-1.7320508075688767),&zwsp;(3.673819061467132e-16,-2),&zwsp;(-0.9999999999999987,-1.732050807568878),&zwsp;(-1.7320508075688767,-1.0000000000000009))</returnvalue>
12240 </para></entry>
12241 </row>
12243 <row>
12244 <entry role="func_table_entry"><para role="func_signature">
12245 <function>polygon</function> ( <type>integer</type>, <type>circle</type> )
12246 <returnvalue>polygon</returnvalue>
12247 </para>
12248 <para>
12249 Converts circle to an <replaceable>n</replaceable>-point polygon.
12250 </para>
12251 <para>
12252 <literal>polygon(4, circle '&lt;(3,0),1&gt;')</literal>
12253 <returnvalue>((2,0),&zwsp;(3,1),&zwsp;(4,1.2246063538223773e-16),&zwsp;(3,-1))</returnvalue>
12254 </para></entry>
12255 </row>
12257 <row>
12258 <entry role="func_table_entry"><para role="func_signature">
12259 <function>polygon</function> ( <type>path</type> )
12260 <returnvalue>polygon</returnvalue>
12261 </para>
12262 <para>
12263 Converts closed path to a polygon with the same list of points.
12264 </para>
12265 <para>
12266 <literal>polygon(path '((0,0),(1,1),(2,0))')</literal>
12267 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12268 </para></entry>
12269 </row>
12271 </tbody>
12272 </tgroup>
12273 </table>
12275 <para>
12276 It is possible to access the two component numbers of a <type>point</type>
12277 as though the point were an array with indexes 0 and 1. For example, if
12278 <literal>t.p</literal> is a <type>point</type> column then
12279 <literal>SELECT p[0] FROM t</literal> retrieves the X coordinate and
12280 <literal>UPDATE t SET p[1] = ...</literal> changes the Y coordinate.
12281 In the same way, a value of type <type>box</type> or <type>lseg</type> can be treated
12282 as an array of two <type>point</type> values.
12283 </para>
12285 </sect1>
12288 <sect1 id="functions-net">
12289 <title>Network Address Functions and Operators</title>
12291 <para>
12292 The IP network address types, <type>cidr</type> and <type>inet</type>,
12293 support the usual comparison operators shown in
12294 <xref linkend="functions-comparison-op-table"/>
12295 as well as the specialized operators and functions shown in
12296 <xref linkend="cidr-inet-operators-table"/> and
12297 <xref linkend="cidr-inet-functions-table"/>.
12298 </para>
12300 <para>
12301 Any <type>cidr</type> value can be cast to <type>inet</type> implicitly;
12302 therefore, the operators and functions shown below as operating on
12303 <type>inet</type> also work on <type>cidr</type> values. (Where there are
12304 separate functions for <type>inet</type> and <type>cidr</type>, it is
12305 because the behavior should be different for the two cases.)
12306 Also, it is permitted to cast an <type>inet</type> value
12307 to <type>cidr</type>. When this is done, any bits to the right of the
12308 netmask are silently zeroed to create a valid <type>cidr</type> value.
12309 </para>
12311 <table id="cidr-inet-operators-table">
12312 <title>IP Address Operators</title>
12313 <tgroup cols="1">
12314 <thead>
12315 <row>
12316 <entry role="func_table_entry"><para role="func_signature">
12317 Operator
12318 </para>
12319 <para>
12320 Description
12321 </para>
12322 <para>
12323 Example(s)
12324 </para></entry>
12325 </row>
12326 </thead>
12328 <tbody>
12329 <row>
12330 <entry role="func_table_entry"><para role="func_signature">
12331 <type>inet</type> <literal>&lt;&lt;</literal> <type>inet</type>
12332 <returnvalue>boolean</returnvalue>
12333 </para>
12334 <para>
12335 Is subnet strictly contained by subnet?
12336 This operator, and the next four, test for subnet inclusion. They
12337 consider only the network parts of the two addresses (ignoring any
12338 bits to the right of the netmasks) and determine whether one network
12339 is identical to or a subnet of the other.
12340 </para>
12341 <para>
12342 <literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal>
12343 <returnvalue>t</returnvalue>
12344 </para>
12345 <para>
12346 <literal>inet '192.168.0.5' &lt;&lt; inet '192.168.1/24'</literal>
12347 <returnvalue>f</returnvalue>
12348 </para>
12349 <para>
12350 <literal>inet '192.168.1/24' &lt;&lt; inet '192.168.1/24'</literal>
12351 <returnvalue>f</returnvalue>
12352 </para></entry>
12353 </row>
12355 <row>
12356 <entry role="func_table_entry"><para role="func_signature">
12357 <type>inet</type> <literal>&lt;&lt;=</literal> <type>inet</type>
12358 <returnvalue>boolean</returnvalue>
12359 </para>
12360 <para>
12361 Is subnet contained by or equal to subnet?
12362 </para>
12363 <para>
12364 <literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal>
12365 <returnvalue>t</returnvalue>
12366 </para></entry>
12367 </row>
12369 <row>
12370 <entry role="func_table_entry"><para role="func_signature">
12371 <type>inet</type> <literal>&gt;&gt;</literal> <type>inet</type>
12372 <returnvalue>boolean</returnvalue>
12373 </para>
12374 <para>
12375 Does subnet strictly contain subnet?
12376 </para>
12377 <para>
12378 <literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal>
12379 <returnvalue>t</returnvalue>
12380 </para></entry>
12381 </row>
12383 <row>
12384 <entry role="func_table_entry"><para role="func_signature">
12385 <type>inet</type> <literal>&gt;&gt;=</literal> <type>inet</type>
12386 <returnvalue>boolean</returnvalue>
12387 </para>
12388 <para>
12389 Does subnet contain or equal subnet?
12390 </para>
12391 <para>
12392 <literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal>
12393 <returnvalue>t</returnvalue>
12394 </para></entry>
12395 </row>
12397 <row>
12398 <entry role="func_table_entry"><para role="func_signature">
12399 <type>inet</type> <literal>&amp;&amp;</literal> <type>inet</type>
12400 <returnvalue>boolean</returnvalue>
12401 </para>
12402 <para>
12403 Does either subnet contain or equal the other?
12404 </para>
12405 <para>
12406 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.1.80/28'</literal>
12407 <returnvalue>t</returnvalue>
12408 </para>
12409 <para>
12410 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.2.0/28'</literal>
12411 <returnvalue>f</returnvalue>
12412 </para></entry>
12413 </row>
12415 <row>
12416 <entry role="func_table_entry"><para role="func_signature">
12417 <literal>~</literal> <type>inet</type>
12418 <returnvalue>inet</returnvalue>
12419 </para>
12420 <para>
12421 Computes bitwise NOT.
12422 </para>
12423 <para>
12424 <literal>~ inet '192.168.1.6'</literal>
12425 <returnvalue>63.87.254.249</returnvalue>
12426 </para></entry>
12427 </row>
12429 <row>
12430 <entry role="func_table_entry"><para role="func_signature">
12431 <type>inet</type> <literal>&amp;</literal> <type>inet</type>
12432 <returnvalue>inet</returnvalue>
12433 </para>
12434 <para>
12435 Computes bitwise AND.
12436 </para>
12437 <para>
12438 <literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal>
12439 <returnvalue>0.0.0.6</returnvalue>
12440 </para></entry>
12441 </row>
12443 <row>
12444 <entry role="func_table_entry"><para role="func_signature">
12445 <type>inet</type> <literal>|</literal> <type>inet</type>
12446 <returnvalue>inet</returnvalue>
12447 </para>
12448 <para>
12449 Computes bitwise OR.
12450 </para>
12451 <para>
12452 <literal>inet '192.168.1.6' | inet '0.0.0.255'</literal>
12453 <returnvalue>192.168.1.255</returnvalue>
12454 </para></entry>
12455 </row>
12457 <row>
12458 <entry role="func_table_entry"><para role="func_signature">
12459 <type>inet</type> <literal>+</literal> <type>bigint</type>
12460 <returnvalue>inet</returnvalue>
12461 </para>
12462 <para>
12463 Adds an offset to an address.
12464 </para>
12465 <para>
12466 <literal>inet '192.168.1.6' + 25</literal>
12467 <returnvalue>192.168.1.31</returnvalue>
12468 </para></entry>
12469 </row>
12471 <row>
12472 <entry role="func_table_entry"><para role="func_signature">
12473 <type>bigint</type> <literal>+</literal> <type>inet</type>
12474 <returnvalue>inet</returnvalue>
12475 </para>
12476 <para>
12477 Adds an offset to an address.
12478 </para>
12479 <para>
12480 <literal>200 + inet '::ffff:fff0:1'</literal>
12481 <returnvalue>::ffff:255.240.0.201</returnvalue>
12482 </para></entry>
12483 </row>
12485 <row>
12486 <entry role="func_table_entry"><para role="func_signature">
12487 <type>inet</type> <literal>-</literal> <type>bigint</type>
12488 <returnvalue>inet</returnvalue>
12489 </para>
12490 <para>
12491 Subtracts an offset from an address.
12492 </para>
12493 <para>
12494 <literal>inet '192.168.1.43' - 36</literal>
12495 <returnvalue>192.168.1.7</returnvalue>
12496 </para></entry>
12497 </row>
12499 <row>
12500 <entry role="func_table_entry"><para role="func_signature">
12501 <type>inet</type> <literal>-</literal> <type>inet</type>
12502 <returnvalue>bigint</returnvalue>
12503 </para>
12504 <para>
12505 Computes the difference of two addresses.
12506 </para>
12507 <para>
12508 <literal>inet '192.168.1.43' - inet '192.168.1.19'</literal>
12509 <returnvalue>24</returnvalue>
12510 </para>
12511 <para>
12512 <literal>inet '::1' - inet '::ffff:1'</literal>
12513 <returnvalue>-4294901760</returnvalue>
12514 </para></entry>
12515 </row>
12516 </tbody>
12517 </tgroup>
12518 </table>
12520 <table id="cidr-inet-functions-table">
12521 <title>IP Address Functions</title>
12522 <tgroup cols="1">
12523 <thead>
12524 <row>
12525 <entry role="func_table_entry"><para role="func_signature">
12526 Function
12527 </para>
12528 <para>
12529 Description
12530 </para>
12531 <para>
12532 Example(s)
12533 </para></entry>
12534 </row>
12535 </thead>
12537 <tbody>
12538 <row>
12539 <entry role="func_table_entry"><para role="func_signature">
12540 <indexterm>
12541 <primary>abbrev</primary>
12542 </indexterm>
12543 <function>abbrev</function> ( <type>inet</type> )
12544 <returnvalue>text</returnvalue>
12545 </para>
12546 <para>
12547 Creates an abbreviated display format as text.
12548 (The result is the same as the <type>inet</type> output function
12549 produces; it is <quote>abbreviated</quote> only in comparison to the
12550 result of an explicit cast to <type>text</type>, which for historical
12551 reasons will never suppress the netmask part.)
12552 </para>
12553 <para>
12554 <literal>abbrev(inet '10.1.0.0/32')</literal>
12555 <returnvalue>10.1.0.0</returnvalue>
12556 </para></entry>
12557 </row>
12559 <row>
12560 <entry role="func_table_entry"><para role="func_signature">
12561 <function>abbrev</function> ( <type>cidr</type> )
12562 <returnvalue>text</returnvalue>
12563 </para>
12564 <para>
12565 Creates an abbreviated display format as text.
12566 (The abbreviation consists of dropping all-zero octets to the right
12567 of the netmask; more examples are in
12568 <xref linkend="datatype-net-cidr-table"/>.)
12569 </para>
12570 <para>
12571 <literal>abbrev(cidr '10.1.0.0/16')</literal>
12572 <returnvalue>10.1/16</returnvalue>
12573 </para></entry>
12574 </row>
12576 <row>
12577 <entry role="func_table_entry"><para role="func_signature">
12578 <indexterm>
12579 <primary>broadcast</primary>
12580 </indexterm>
12581 <function>broadcast</function> ( <type>inet</type> )
12582 <returnvalue>inet</returnvalue>
12583 </para>
12584 <para>
12585 Computes the broadcast address for the address's network.
12586 </para>
12587 <para>
12588 <literal>broadcast(inet '192.168.1.5/24')</literal>
12589 <returnvalue>192.168.1.255/24</returnvalue>
12590 </para></entry>
12591 </row>
12593 <row>
12594 <entry role="func_table_entry"><para role="func_signature">
12595 <indexterm>
12596 <primary>family</primary>
12597 </indexterm>
12598 <function>family</function> ( <type>inet</type> )
12599 <returnvalue>integer</returnvalue>
12600 </para>
12601 <para>
12602 Returns the address's family: <literal>4</literal> for IPv4,
12603 <literal>6</literal> for IPv6.
12604 </para>
12605 <para>
12606 <literal>family(inet '::1')</literal>
12607 <returnvalue>6</returnvalue>
12608 </para></entry>
12609 </row>
12611 <row>
12612 <entry role="func_table_entry"><para role="func_signature">
12613 <indexterm>
12614 <primary>host</primary>
12615 </indexterm>
12616 <function>host</function> ( <type>inet</type> )
12617 <returnvalue>text</returnvalue>
12618 </para>
12619 <para>
12620 Returns the IP address as text, ignoring the netmask.
12621 </para>
12622 <para>
12623 <literal>host(inet '192.168.1.0/24')</literal>
12624 <returnvalue>192.168.1.0</returnvalue>
12625 </para></entry>
12626 </row>
12628 <row>
12629 <entry role="func_table_entry"><para role="func_signature">
12630 <indexterm>
12631 <primary>hostmask</primary>
12632 </indexterm>
12633 <function>hostmask</function> ( <type>inet</type> )
12634 <returnvalue>inet</returnvalue>
12635 </para>
12636 <para>
12637 Computes the host mask for the address's network.
12638 </para>
12639 <para>
12640 <literal>hostmask(inet '192.168.23.20/30')</literal>
12641 <returnvalue>0.0.0.3</returnvalue>
12642 </para></entry>
12643 </row>
12645 <row>
12646 <entry role="func_table_entry"><para role="func_signature">
12647 <indexterm>
12648 <primary>inet_merge</primary>
12649 </indexterm>
12650 <function>inet_merge</function> ( <type>inet</type>, <type>inet</type> )
12651 <returnvalue>cidr</returnvalue>
12652 </para>
12653 <para>
12654 Computes the smallest network that includes both of the given networks.
12655 </para>
12656 <para>
12657 <literal>inet_merge(inet '192.168.1.5/24', inet '192.168.2.5/24')</literal>
12658 <returnvalue>192.168.0.0/22</returnvalue>
12659 </para></entry>
12660 </row>
12662 <row>
12663 <entry role="func_table_entry"><para role="func_signature">
12664 <indexterm>
12665 <primary>inet_same_family</primary>
12666 </indexterm>
12667 <function>inet_same_family</function> ( <type>inet</type>, <type>inet</type> )
12668 <returnvalue>boolean</returnvalue>
12669 </para>
12670 <para>
12671 Tests whether the addresses belong to the same IP family.
12672 </para>
12673 <para>
12674 <literal>inet_same_family(inet '192.168.1.5/24', inet '::1')</literal>
12675 <returnvalue>f</returnvalue>
12676 </para></entry>
12677 </row>
12679 <row>
12680 <entry role="func_table_entry"><para role="func_signature">
12681 <indexterm>
12682 <primary>masklen</primary>
12683 </indexterm>
12684 <function>masklen</function> ( <type>inet</type> )
12685 <returnvalue>integer</returnvalue>
12686 </para>
12687 <para>
12688 Returns the netmask length in bits.
12689 </para>
12690 <para>
12691 <literal>masklen(inet '192.168.1.5/24')</literal>
12692 <returnvalue>24</returnvalue>
12693 </para></entry>
12694 </row>
12696 <row>
12697 <entry role="func_table_entry"><para role="func_signature">
12698 <indexterm>
12699 <primary>netmask</primary>
12700 </indexterm>
12701 <function>netmask</function> ( <type>inet</type> )
12702 <returnvalue>inet</returnvalue>
12703 </para>
12704 <para>
12705 Computes the network mask for the address's network.
12706 </para>
12707 <para>
12708 <literal>netmask(inet '192.168.1.5/24')</literal>
12709 <returnvalue>255.255.255.0</returnvalue>
12710 </para></entry>
12711 </row>
12713 <row>
12714 <entry role="func_table_entry"><para role="func_signature">
12715 <indexterm>
12716 <primary>network</primary>
12717 </indexterm>
12718 <function>network</function> ( <type>inet</type> )
12719 <returnvalue>cidr</returnvalue>
12720 </para>
12721 <para>
12722 Returns the network part of the address, zeroing out
12723 whatever is to the right of the netmask.
12724 (This is equivalent to casting the value to <type>cidr</type>.)
12725 </para>
12726 <para>
12727 <literal>network(inet '192.168.1.5/24')</literal>
12728 <returnvalue>192.168.1.0/24</returnvalue>
12729 </para></entry>
12730 </row>
12732 <row>
12733 <entry role="func_table_entry"><para role="func_signature">
12734 <indexterm>
12735 <primary>set_masklen</primary>
12736 </indexterm>
12737 <function>set_masklen</function> ( <type>inet</type>, <type>integer</type> )
12738 <returnvalue>inet</returnvalue>
12739 </para>
12740 <para>
12741 Sets the netmask length for an <type>inet</type> value.
12742 The address part does not change.
12743 </para>
12744 <para>
12745 <literal>set_masklen(inet '192.168.1.5/24', 16)</literal>
12746 <returnvalue>192.168.1.5/16</returnvalue>
12747 </para></entry>
12748 </row>
12750 <row>
12751 <entry role="func_table_entry"><para role="func_signature">
12752 <function>set_masklen</function> ( <type>cidr</type>, <type>integer</type> )
12753 <returnvalue>cidr</returnvalue>
12754 </para>
12755 <para>
12756 Sets the netmask length for a <type>cidr</type> value.
12757 Address bits to the right of the new netmask are set to zero.
12758 </para>
12759 <para>
12760 <literal>set_masklen(cidr '192.168.1.0/24', 16)</literal>
12761 <returnvalue>192.168.0.0/16</returnvalue>
12762 </para></entry>
12763 </row>
12765 <row>
12766 <entry role="func_table_entry"><para role="func_signature">
12767 <indexterm>
12768 <primary>text</primary>
12769 </indexterm>
12770 <function>text</function> ( <type>inet</type> )
12771 <returnvalue>text</returnvalue>
12772 </para>
12773 <para>
12774 Returns the unabbreviated IP address and netmask length as text.
12775 (This has the same result as an explicit cast to <type>text</type>.)
12776 </para>
12777 <para>
12778 <literal>text(inet '192.168.1.5')</literal>
12779 <returnvalue>192.168.1.5/32</returnvalue>
12780 </para></entry>
12781 </row>
12782 </tbody>
12783 </tgroup>
12784 </table>
12786 <tip>
12787 <para>
12788 The <function>abbrev</function>, <function>host</function>,
12789 and <function>text</function> functions are primarily intended to offer
12790 alternative display formats for IP addresses.
12791 </para>
12792 </tip>
12794 <para>
12795 The MAC address types, <type>macaddr</type> and <type>macaddr8</type>,
12796 support the usual comparison operators shown in
12797 <xref linkend="functions-comparison-op-table"/>
12798 as well as the specialized functions shown in
12799 <xref linkend="macaddr-functions-table"/>.
12800 In addition, they support the bitwise logical operators
12801 <literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>
12802 (NOT, AND and OR), just as shown above for IP addresses.
12803 </para>
12805 <table id="macaddr-functions-table">
12806 <title>MAC Address Functions</title>
12807 <tgroup cols="1">
12808 <thead>
12809 <row>
12810 <entry role="func_table_entry"><para role="func_signature">
12811 Function
12812 </para>
12813 <para>
12814 Description
12815 </para>
12816 <para>
12817 Example(s)
12818 </para></entry>
12819 </row>
12820 </thead>
12822 <tbody>
12823 <row>
12824 <entry role="func_table_entry"><para role="func_signature">
12825 <indexterm>
12826 <primary>trunc</primary>
12827 </indexterm>
12828 <function>trunc</function> ( <type>macaddr</type> )
12829 <returnvalue>macaddr</returnvalue>
12830 </para>
12831 <para>
12832 Sets the last 3 bytes of the address to zero. The remaining prefix
12833 can be associated with a particular manufacturer (using data not
12834 included in <productname>PostgreSQL</productname>).
12835 </para>
12836 <para>
12837 <literal>trunc(macaddr '12:34:56:78:90:ab')</literal>
12838 <returnvalue>12:34:56:00:00:00</returnvalue>
12839 </para></entry>
12840 </row>
12842 <row>
12843 <entry role="func_table_entry"><para role="func_signature">
12844 <function>trunc</function> ( <type>macaddr8</type> )
12845 <returnvalue>macaddr8</returnvalue>
12846 </para>
12847 <para>
12848 Sets the last 5 bytes of the address to zero. The remaining prefix
12849 can be associated with a particular manufacturer (using data not
12850 included in <productname>PostgreSQL</productname>).
12851 </para>
12852 <para>
12853 <literal>trunc(macaddr8 '12:34:56:78:90:ab:cd:ef')</literal>
12854 <returnvalue>12:34:56:00:00:00:00:00</returnvalue>
12855 </para></entry>
12856 </row>
12858 <row>
12859 <entry role="func_table_entry"><para role="func_signature">
12860 <indexterm>
12861 <primary>macaddr8_set7bit</primary>
12862 </indexterm>
12863 <function>macaddr8_set7bit</function> ( <type>macaddr8</type> )
12864 <returnvalue>macaddr8</returnvalue>
12865 </para>
12866 <para>
12867 Sets the 7th bit of the address to one, creating what is known as
12868 modified EUI-64, for inclusion in an IPv6 address.
12869 </para>
12870 <para>
12871 <literal>macaddr8_set7bit(macaddr8 '00:34:56:ab:cd:ef')</literal>
12872 <returnvalue>02:34:56:ff:fe:ab:cd:ef</returnvalue>
12873 </para></entry>
12874 </row>
12875 </tbody>
12876 </tgroup>
12877 </table>
12879 </sect1>
12882 <sect1 id="functions-textsearch">
12883 <title>Text Search Functions and Operators</title>
12885 <indexterm zone="datatype-textsearch">
12886 <primary>full text search</primary>
12887 <secondary>functions and operators</secondary>
12888 </indexterm>
12890 <indexterm zone="datatype-textsearch">
12891 <primary>text search</primary>
12892 <secondary>functions and operators</secondary>
12893 </indexterm>
12895 <para>
12896 <xref linkend="textsearch-operators-table"/>,
12897 <xref linkend="textsearch-functions-table"/> and
12898 <xref linkend="textsearch-functions-debug-table"/>
12899 summarize the functions and operators that are provided
12900 for full text searching. See <xref linkend="textsearch"/> for a detailed
12901 explanation of <productname>PostgreSQL</productname>'s text search
12902 facility.
12903 </para>
12905 <table id="textsearch-operators-table">
12906 <title>Text Search Operators</title>
12907 <tgroup cols="1">
12908 <thead>
12909 <row>
12910 <entry role="func_table_entry"><para role="func_signature">
12911 Operator
12912 </para>
12913 <para>
12914 Description
12915 </para>
12916 <para>
12917 Example(s)
12918 </para></entry>
12919 </row>
12920 </thead>
12922 <tbody>
12923 <row>
12924 <entry role="func_table_entry"><para role="func_signature">
12925 <type>tsvector</type> <literal>@@</literal> <type>tsquery</type>
12926 <returnvalue>boolean</returnvalue>
12927 </para>
12928 <para role="func_signature">
12929 <type>tsquery</type> <literal>@@</literal> <type>tsvector</type>
12930 <returnvalue>boolean</returnvalue>
12931 </para>
12932 <para>
12933 Does <type>tsvector</type> match <type>tsquery</type>?
12934 (The arguments can be given in either order.)
12935 </para>
12936 <para>
12937 <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal>
12938 <returnvalue>t</returnvalue>
12939 </para></entry>
12940 </row>
12942 <row>
12943 <entry role="func_table_entry"><para role="func_signature">
12944 <type>text</type> <literal>@@</literal> <type>tsquery</type>
12945 <returnvalue>boolean</returnvalue>
12946 </para>
12947 <para>
12948 Does text string, after implicit invocation
12949 of <function>to_tsvector()</function>, match <type>tsquery</type>?
12950 </para>
12951 <para>
12952 <literal>'fat cats ate rats' @@ to_tsquery('cat &amp; rat')</literal>
12953 <returnvalue>t</returnvalue>
12954 </para></entry>
12955 </row>
12957 <row>
12958 <entry role="func_table_entry"><para role="func_signature">
12959 <type>tsvector</type> <literal>@@@</literal> <type>tsquery</type>
12960 <returnvalue>boolean</returnvalue>
12961 </para>
12962 <para role="func_signature">
12963 <type>tsquery</type> <literal>@@@</literal> <type>tsvector</type>
12964 <returnvalue>boolean</returnvalue>
12965 </para>
12966 <para>
12967 This is a deprecated synonym for <literal>@@</literal>.
12968 </para>
12969 <para>
12970 <literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal>
12971 <returnvalue>t</returnvalue>
12972 </para></entry>
12973 </row>
12975 <row>
12976 <entry role="func_table_entry"><para role="func_signature">
12977 <type>tsvector</type> <literal>||</literal> <type>tsvector</type>
12978 <returnvalue>tsvector</returnvalue>
12979 </para>
12980 <para>
12981 Concatenates two <type>tsvector</type>s. If both inputs contain
12982 lexeme positions, the second input's positions are adjusted
12983 accordingly.
12984 </para>
12985 <para>
12986 <literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal>
12987 <returnvalue>'a':1 'b':2,5 'c':3 'd':4</returnvalue>
12988 </para></entry>
12989 </row>
12991 <row>
12992 <entry role="func_table_entry"><para role="func_signature">
12993 <type>tsquery</type> <literal>&amp;&amp;</literal> <type>tsquery</type>
12994 <returnvalue>tsquery</returnvalue>
12995 </para>
12996 <para>
12997 ANDs two <type>tsquery</type>s together, producing a query that
12998 matches documents that match both input queries.
12999 </para>
13000 <para>
13001 <literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal>
13002 <returnvalue>( 'fat' | 'rat' ) &amp; 'cat'</returnvalue>
13003 </para></entry>
13004 </row>
13006 <row>
13007 <entry role="func_table_entry"><para role="func_signature">
13008 <type>tsquery</type> <literal>||</literal> <type>tsquery</type>
13009 <returnvalue>tsquery</returnvalue>
13010 </para>
13011 <para>
13012 ORs two <type>tsquery</type>s together, producing a query that
13013 matches documents that match either input query.
13014 </para>
13015 <para>
13016 <literal>'fat | rat'::tsquery || 'cat'::tsquery</literal>
13017 <returnvalue>'fat' | 'rat' | 'cat'</returnvalue>
13018 </para></entry>
13019 </row>
13021 <row>
13022 <entry role="func_table_entry"><para role="func_signature">
13023 <literal>!!</literal> <type>tsquery</type>
13024 <returnvalue>tsquery</returnvalue>
13025 </para>
13026 <para>
13027 Negates a <type>tsquery</type>, producing a query that matches
13028 documents that do not match the input query.
13029 </para>
13030 <para>
13031 <literal>!! 'cat'::tsquery</literal>
13032 <returnvalue>!'cat'</returnvalue>
13033 </para></entry>
13034 </row>
13036 <row>
13037 <entry role="func_table_entry"><para role="func_signature">
13038 <type>tsquery</type> <literal>&lt;-&gt;</literal> <type>tsquery</type>
13039 <returnvalue>tsquery</returnvalue>
13040 </para>
13041 <para>
13042 Constructs a phrase query, which matches if the two input queries
13043 match at successive lexemes.
13044 </para>
13045 <para>
13046 <literal>to_tsquery('fat') &lt;-&gt; to_tsquery('rat')</literal>
13047 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
13048 </para></entry>
13049 </row>
13051 <row>
13052 <entry role="func_table_entry"><para role="func_signature">
13053 <type>tsquery</type> <literal>@&gt;</literal> <type>tsquery</type>
13054 <returnvalue>boolean</returnvalue>
13055 </para>
13056 <para>
13057 Does first <type>tsquery</type> contain the second? (This considers
13058 only whether all the lexemes appearing in one query appear in the
13059 other, ignoring the combining operators.)
13060 </para>
13061 <para>
13062 <literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal>
13063 <returnvalue>f</returnvalue>
13064 </para></entry>
13065 </row>
13067 <row>
13068 <entry role="func_table_entry"><para role="func_signature">
13069 <type>tsquery</type> <literal>&lt;@</literal> <type>tsquery</type>
13070 <returnvalue>boolean</returnvalue>
13071 </para>
13072 <para>
13073 Is first <type>tsquery</type> contained in the second? (This
13074 considers only whether all the lexemes appearing in one query appear
13075 in the other, ignoring the combining operators.)
13076 </para>
13077 <para>
13078 <literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal>
13079 <returnvalue>t</returnvalue>
13080 </para>
13081 <para>
13082 <literal>'cat'::tsquery &lt;@ '!cat &amp; rat'::tsquery</literal>
13083 <returnvalue>t</returnvalue>
13084 </para></entry>
13085 </row>
13086 </tbody>
13087 </tgroup>
13088 </table>
13090 <para>
13091 In addition to these specialized operators, the usual comparison
13092 operators shown in <xref linkend="functions-comparison-op-table"/> are
13093 available for types <type>tsvector</type> and <type>tsquery</type>.
13094 These are not very
13095 useful for text searching but allow, for example, unique indexes to be
13096 built on columns of these types.
13097 </para>
13099 <table id="textsearch-functions-table">
13100 <title>Text Search Functions</title>
13101 <tgroup cols="1">
13102 <thead>
13103 <row>
13104 <entry role="func_table_entry"><para role="func_signature">
13105 Function
13106 </para>
13107 <para>
13108 Description
13109 </para>
13110 <para>
13111 Example(s)
13112 </para></entry>
13113 </row>
13114 </thead>
13116 <tbody>
13117 <row>
13118 <entry role="func_table_entry"><para role="func_signature">
13119 <indexterm>
13120 <primary>array_to_tsvector</primary>
13121 </indexterm>
13122 <function>array_to_tsvector</function> ( <type>text[]</type> )
13123 <returnvalue>tsvector</returnvalue>
13124 </para>
13125 <para>
13126 Converts an array of text strings to a <type>tsvector</type>.
13127 The given strings are used as lexemes as-is, without further
13128 processing. Array elements must not be empty strings
13129 or <literal>NULL</literal>.
13130 </para>
13131 <para>
13132 <literal>array_to_tsvector('{fat,cat,rat}'::text[])</literal>
13133 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13134 </para></entry>
13135 </row>
13137 <row>
13138 <entry role="func_table_entry"><para role="func_signature">
13139 <indexterm>
13140 <primary>get_current_ts_config</primary>
13141 </indexterm>
13142 <function>get_current_ts_config</function> ( )
13143 <returnvalue>regconfig</returnvalue>
13144 </para>
13145 <para>
13146 Returns the OID of the current default text search configuration
13147 (as set by <xref linkend="guc-default-text-search-config"/>).
13148 </para>
13149 <para>
13150 <literal>get_current_ts_config()</literal>
13151 <returnvalue>english</returnvalue>
13152 </para></entry>
13153 </row>
13155 <row>
13156 <entry role="func_table_entry"><para role="func_signature">
13157 <indexterm>
13158 <primary>length</primary>
13159 </indexterm>
13160 <function>length</function> ( <type>tsvector</type> )
13161 <returnvalue>integer</returnvalue>
13162 </para>
13163 <para>
13164 Returns the number of lexemes in the <type>tsvector</type>.
13165 </para>
13166 <para>
13167 <literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13168 <returnvalue>3</returnvalue>
13169 </para></entry>
13170 </row>
13172 <row>
13173 <entry role="func_table_entry"><para role="func_signature">
13174 <indexterm>
13175 <primary>numnode</primary>
13176 </indexterm>
13177 <function>numnode</function> ( <type>tsquery</type> )
13178 <returnvalue>integer</returnvalue>
13179 </para>
13180 <para>
13181 Returns the number of lexemes plus operators in
13182 the <type>tsquery</type>.
13183 </para>
13184 <para>
13185 <literal>numnode('(fat &amp; rat) | cat'::tsquery)</literal>
13186 <returnvalue>5</returnvalue>
13187 </para></entry>
13188 </row>
13190 <row>
13191 <entry role="func_table_entry"><para role="func_signature">
13192 <indexterm>
13193 <primary>plainto_tsquery</primary>
13194 </indexterm>
13195 <function>plainto_tsquery</function> (
13196 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13197 <parameter>query</parameter> <type>text</type> )
13198 <returnvalue>tsquery</returnvalue>
13199 </para>
13200 <para>
13201 Converts text to a <type>tsquery</type>, normalizing words according to
13202 the specified or default configuration. Any punctuation in the string
13203 is ignored (it does not determine query operators). The resulting
13204 query matches documents containing all non-stopwords in the text.
13205 </para>
13206 <para>
13207 <literal>plainto_tsquery('english', 'The Fat Rats')</literal>
13208 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13209 </para></entry>
13210 </row>
13212 <row>
13213 <entry role="func_table_entry"><para role="func_signature">
13214 <indexterm>
13215 <primary>phraseto_tsquery</primary>
13216 </indexterm>
13217 <function>phraseto_tsquery</function> (
13218 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13219 <parameter>query</parameter> <type>text</type> )
13220 <returnvalue>tsquery</returnvalue>
13221 </para>
13222 <para>
13223 Converts text to a <type>tsquery</type>, normalizing words according to
13224 the specified or default configuration. Any punctuation in the string
13225 is ignored (it does not determine query operators). The resulting
13226 query matches phrases containing all non-stopwords in the text.
13227 </para>
13228 <para>
13229 <literal>phraseto_tsquery('english', 'The Fat Rats')</literal>
13230 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
13231 </para>
13232 <para>
13233 <literal>phraseto_tsquery('english', 'The Cat and Rats')</literal>
13234 <returnvalue>'cat' &lt;2&gt; 'rat'</returnvalue>
13235 </para></entry>
13236 </row>
13238 <row>
13239 <entry role="func_table_entry"><para role="func_signature">
13240 <indexterm>
13241 <primary>websearch_to_tsquery</primary>
13242 </indexterm>
13243 <function>websearch_to_tsquery</function> (
13244 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13245 <parameter>query</parameter> <type>text</type> )
13246 <returnvalue>tsquery</returnvalue>
13247 </para>
13248 <para>
13249 Converts text to a <type>tsquery</type>, normalizing words according
13250 to the specified or default configuration. Quoted word sequences are
13251 converted to phrase tests. The word <quote>or</quote> is understood
13252 as producing an OR operator, and a dash produces a NOT operator;
13253 other punctuation is ignored.
13254 This approximates the behavior of some common web search tools.
13255 </para>
13256 <para>
13257 <literal>websearch_to_tsquery('english', '"fat rat" or cat dog')</literal>
13258 <returnvalue>'fat' &lt;-&gt; 'rat' | 'cat' &amp; 'dog'</returnvalue>
13259 </para></entry>
13260 </row>
13262 <row>
13263 <entry role="func_table_entry"><para role="func_signature">
13264 <indexterm>
13265 <primary>querytree</primary>
13266 </indexterm>
13267 <function>querytree</function> ( <type>tsquery</type> )
13268 <returnvalue>text</returnvalue>
13269 </para>
13270 <para>
13271 Produces a representation of the indexable portion of
13272 a <type>tsquery</type>. A result that is empty or
13273 just <literal>T</literal> indicates a non-indexable query.
13274 </para>
13275 <para>
13276 <literal>querytree('foo &amp; ! bar'::tsquery)</literal>
13277 <returnvalue>'foo'</returnvalue>
13278 </para></entry>
13279 </row>
13281 <row>
13282 <entry role="func_table_entry"><para role="func_signature">
13283 <indexterm>
13284 <primary>setweight</primary>
13285 </indexterm>
13286 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type> )
13287 <returnvalue>tsvector</returnvalue>
13288 </para>
13289 <para>
13290 Assigns the specified <parameter>weight</parameter> to each element
13291 of the <parameter>vector</parameter>.
13292 </para>
13293 <para>
13294 <literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal>
13295 <returnvalue>'cat':3A 'fat':2A,4A 'rat':5A</returnvalue>
13296 </para></entry>
13297 </row>
13299 <row>
13300 <entry role="func_table_entry"><para role="func_signature">
13301 <indexterm>
13302 <primary>setweight</primary>
13303 <secondary>setweight for specific lexeme(s)</secondary>
13304 </indexterm>
13305 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13306 <returnvalue>tsvector</returnvalue>
13307 </para>
13308 <para>
13309 Assigns the specified <parameter>weight</parameter> to elements
13310 of the <parameter>vector</parameter> that are listed
13311 in <parameter>lexemes</parameter>.
13312 The strings in <parameter>lexemes</parameter> are taken as lexemes
13313 as-is, without further processing. Strings that do not match any
13314 lexeme in <parameter>vector</parameter> are ignored.
13315 </para>
13316 <para>
13317 <literal>setweight('fat:2,4 cat:3 rat:5,6B'::tsvector, 'A', '{cat,rat}')</literal>
13318 <returnvalue>'cat':3A 'fat':2,4 'rat':5A,6A</returnvalue>
13319 </para></entry>
13320 </row>
13322 <row>
13323 <entry role="func_table_entry"><para role="func_signature">
13324 <indexterm>
13325 <primary>strip</primary>
13326 </indexterm>
13327 <function>strip</function> ( <type>tsvector</type> )
13328 <returnvalue>tsvector</returnvalue>
13329 </para>
13330 <para>
13331 Removes positions and weights from the <type>tsvector</type>.
13332 </para>
13333 <para>
13334 <literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13335 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13336 </para></entry>
13337 </row>
13339 <row>
13340 <entry role="func_table_entry"><para role="func_signature">
13341 <indexterm>
13342 <primary>to_tsquery</primary>
13343 </indexterm>
13344 <function>to_tsquery</function> (
13345 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13346 <parameter>query</parameter> <type>text</type> )
13347 <returnvalue>tsquery</returnvalue>
13348 </para>
13349 <para>
13350 Converts text to a <type>tsquery</type>, normalizing words according to
13351 the specified or default configuration. The words must be combined
13352 by valid <type>tsquery</type> operators.
13353 </para>
13354 <para>
13355 <literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal>
13356 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13357 </para></entry>
13358 </row>
13360 <row>
13361 <entry role="func_table_entry"><para role="func_signature">
13362 <indexterm>
13363 <primary>to_tsvector</primary>
13364 </indexterm>
13365 <function>to_tsvector</function> (
13366 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13367 <parameter>document</parameter> <type>text</type> )
13368 <returnvalue>tsvector</returnvalue>
13369 </para>
13370 <para>
13371 Converts text to a <type>tsvector</type>, normalizing words according
13372 to the specified or default configuration. Position information is
13373 included in the result.
13374 </para>
13375 <para>
13376 <literal>to_tsvector('english', 'The Fat Rats')</literal>
13377 <returnvalue>'fat':2 'rat':3</returnvalue>
13378 </para></entry>
13379 </row>
13381 <row>
13382 <entry role="func_table_entry"><para role="func_signature">
13383 <function>to_tsvector</function> (
13384 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13385 <parameter>document</parameter> <type>json</type> )
13386 <returnvalue>tsvector</returnvalue>
13387 </para>
13388 <para role="func_signature">
13389 <function>to_tsvector</function> (
13390 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13391 <parameter>document</parameter> <type>jsonb</type> )
13392 <returnvalue>tsvector</returnvalue>
13393 </para>
13394 <para>
13395 Converts each string value in the JSON document to
13396 a <type>tsvector</type>, normalizing words according to the specified
13397 or default configuration. The results are then concatenated in
13398 document order to produce the output. Position information is
13399 generated as though one stopword exists between each pair of string
13400 values. (Beware that <quote>document order</quote> of the fields of a
13401 JSON object is implementation-dependent when the input
13402 is <type>jsonb</type>; observe the difference in the examples.)
13403 </para>
13404 <para>
13405 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::json)</literal>
13406 <returnvalue>'dog':5 'fat':2 'rat':3</returnvalue>
13407 </para>
13408 <para>
13409 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::jsonb)</literal>
13410 <returnvalue>'dog':1 'fat':4 'rat':5</returnvalue>
13411 </para></entry>
13412 </row>
13414 <row>
13415 <entry role="func_table_entry"><para role="func_signature">
13416 <indexterm>
13417 <primary>json_to_tsvector</primary>
13418 </indexterm>
13419 <function>json_to_tsvector</function> (
13420 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13421 <parameter>document</parameter> <type>json</type>,
13422 <parameter>filter</parameter> <type>jsonb</type> )
13423 <returnvalue>tsvector</returnvalue>
13424 </para>
13425 <para role="func_signature">
13426 <indexterm>
13427 <primary>jsonb_to_tsvector</primary>
13428 </indexterm>
13429 <function>jsonb_to_tsvector</function> (
13430 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13431 <parameter>document</parameter> <type>jsonb</type>,
13432 <parameter>filter</parameter> <type>jsonb</type> )
13433 <returnvalue>tsvector</returnvalue>
13434 </para>
13435 <para>
13436 Selects each item in the JSON document that is requested by
13437 the <parameter>filter</parameter> and converts each one to
13438 a <type>tsvector</type>, normalizing words according to the specified
13439 or default configuration. The results are then concatenated in
13440 document order to produce the output. Position information is
13441 generated as though one stopword exists between each pair of selected
13442 items. (Beware that <quote>document order</quote> of the fields of a
13443 JSON object is implementation-dependent when the input
13444 is <type>jsonb</type>.)
13445 The <parameter>filter</parameter> must be a <type>jsonb</type>
13446 array containing zero or more of these keywords:
13447 <literal>"string"</literal> (to include all string values),
13448 <literal>"numeric"</literal> (to include all numeric values),
13449 <literal>"boolean"</literal> (to include all boolean values),
13450 <literal>"key"</literal> (to include all keys), or
13451 <literal>"all"</literal> (to include all the above).
13452 As a special case, the <parameter>filter</parameter> can also be a
13453 simple JSON value that is one of these keywords.
13454 </para>
13455 <para>
13456 <literal>json_to_tsvector('english', '{"a": "The Fat Rats", "b": 123}'::json, '["string", "numeric"]')</literal>
13457 <returnvalue>'123':5 'fat':2 'rat':3</returnvalue>
13458 </para>
13459 <para>
13460 <literal>json_to_tsvector('english', '{"cat": "The Fat Rats", "dog": 123}'::json, '"all"')</literal>
13461 <returnvalue>'123':9 'cat':1 'dog':7 'fat':4 'rat':5</returnvalue>
13462 </para></entry>
13463 </row>
13465 <row>
13466 <entry role="func_table_entry"><para role="func_signature">
13467 <indexterm>
13468 <primary>ts_delete</primary>
13469 </indexterm>
13470 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexeme</parameter> <type>text</type> )
13471 <returnvalue>tsvector</returnvalue>
13472 </para>
13473 <para>
13474 Removes any occurrence of the given <parameter>lexeme</parameter>
13475 from the <parameter>vector</parameter>.
13476 The <parameter>lexeme</parameter> string is treated as a lexeme as-is,
13477 without further processing.
13478 </para>
13479 <para>
13480 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, 'fat')</literal>
13481 <returnvalue>'cat':3 'rat':5A</returnvalue>
13482 </para></entry>
13483 </row>
13485 <row>
13486 <entry role="func_table_entry"><para role="func_signature">
13487 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13488 <returnvalue>tsvector</returnvalue>
13489 </para>
13490 <para>
13491 Removes any occurrences of the lexemes
13492 in <parameter>lexemes</parameter>
13493 from the <parameter>vector</parameter>.
13494 The strings in <parameter>lexemes</parameter> are taken as lexemes
13495 as-is, without further processing. Strings that do not match any
13496 lexeme in <parameter>vector</parameter> are ignored.
13497 </para>
13498 <para>
13499 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, ARRAY['fat','rat'])</literal>
13500 <returnvalue>'cat':3</returnvalue>
13501 </para></entry>
13502 </row>
13504 <row>
13505 <entry role="func_table_entry"><para role="func_signature">
13506 <indexterm>
13507 <primary>ts_filter</primary>
13508 </indexterm>
13509 <function>ts_filter</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weights</parameter> <type>"char"[]</type> )
13510 <returnvalue>tsvector</returnvalue>
13511 </para>
13512 <para>
13513 Selects only elements with the given <parameter>weights</parameter>
13514 from the <parameter>vector</parameter>.
13515 </para>
13516 <para>
13517 <literal>ts_filter('fat:2,4 cat:3b,7c rat:5A'::tsvector, '{a,b}')</literal>
13518 <returnvalue>'cat':3B 'rat':5A</returnvalue>
13519 </para></entry>
13520 </row>
13522 <row>
13523 <entry role="func_table_entry"><para role="func_signature">
13524 <indexterm>
13525 <primary>ts_headline</primary>
13526 </indexterm>
13527 <function>ts_headline</function> (
13528 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13529 <parameter>document</parameter> <type>text</type>,
13530 <parameter>query</parameter> <type>tsquery</type>
13531 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13532 <returnvalue>text</returnvalue>
13533 </para>
13534 <para>
13535 Displays, in an abbreviated form, the match(es) for
13536 the <parameter>query</parameter> in
13537 the <parameter>document</parameter>, which must be raw text not
13538 a <type>tsvector</type>. Words in the document are normalized
13539 according to the specified or default configuration before matching to
13540 the query. Use of this function is discussed in
13541 <xref linkend="textsearch-headline"/>, which also describes the
13542 available <parameter>options</parameter>.
13543 </para>
13544 <para>
13545 <literal>ts_headline('The fat cat ate the rat.', 'cat')</literal>
13546 <returnvalue>The fat &lt;b&gt;cat&lt;/b&gt; ate the rat.</returnvalue>
13547 </para></entry>
13548 </row>
13550 <row>
13551 <entry role="func_table_entry"><para role="func_signature">
13552 <function>ts_headline</function> (
13553 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13554 <parameter>document</parameter> <type>json</type>,
13555 <parameter>query</parameter> <type>tsquery</type>
13556 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13557 <returnvalue>text</returnvalue>
13558 </para>
13559 <para role="func_signature">
13560 <function>ts_headline</function> (
13561 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13562 <parameter>document</parameter> <type>jsonb</type>,
13563 <parameter>query</parameter> <type>tsquery</type>
13564 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13565 <returnvalue>text</returnvalue>
13566 </para>
13567 <para>
13568 Displays, in an abbreviated form, match(es) for
13569 the <parameter>query</parameter> that occur in string values
13570 within the JSON <parameter>document</parameter>.
13571 See <xref linkend="textsearch-headline"/> for more details.
13572 </para>
13573 <para>
13574 <literal>ts_headline('{"cat":"raining cats and dogs"}'::jsonb, 'cat')</literal>
13575 <returnvalue>{"cat": "raining &lt;b&gt;cats&lt;/b&gt; and dogs"}</returnvalue>
13576 </para></entry>
13577 </row>
13579 <row>
13580 <entry role="func_table_entry"><para role="func_signature">
13581 <indexterm>
13582 <primary>ts_rank</primary>
13583 </indexterm>
13584 <function>ts_rank</function> (
13585 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13586 <parameter>vector</parameter> <type>tsvector</type>,
13587 <parameter>query</parameter> <type>tsquery</type>
13588 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13589 <returnvalue>real</returnvalue>
13590 </para>
13591 <para>
13592 Computes a score showing how well
13593 the <parameter>vector</parameter> matches
13594 the <parameter>query</parameter>. See
13595 <xref linkend="textsearch-ranking"/> for details.
13596 </para>
13597 <para>
13598 <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')</literal>
13599 <returnvalue>0.06079271</returnvalue>
13600 </para></entry>
13601 </row>
13603 <row>
13604 <entry role="func_table_entry"><para role="func_signature">
13605 <indexterm>
13606 <primary>ts_rank_cd</primary>
13607 </indexterm>
13608 <function>ts_rank_cd</function> (
13609 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13610 <parameter>vector</parameter> <type>tsvector</type>,
13611 <parameter>query</parameter> <type>tsquery</type>
13612 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13613 <returnvalue>real</returnvalue>
13614 </para>
13615 <para>
13616 Computes a score showing how well
13617 the <parameter>vector</parameter> matches
13618 the <parameter>query</parameter>, using a cover density
13619 algorithm. See <xref linkend="textsearch-ranking"/> for details.
13620 </para>
13621 <para>
13622 <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')</literal>
13623 <returnvalue>0.1</returnvalue>
13624 </para></entry>
13625 </row>
13627 <row>
13628 <entry role="func_table_entry"><para role="func_signature">
13629 <indexterm>
13630 <primary>ts_rewrite</primary>
13631 </indexterm>
13632 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13633 <parameter>target</parameter> <type>tsquery</type>,
13634 <parameter>substitute</parameter> <type>tsquery</type> )
13635 <returnvalue>tsquery</returnvalue>
13636 </para>
13637 <para>
13638 Replaces occurrences of <parameter>target</parameter>
13639 with <parameter>substitute</parameter>
13640 within the <parameter>query</parameter>.
13641 See <xref linkend="textsearch-query-rewriting"/> for details.
13642 </para>
13643 <para>
13644 <literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal>
13645 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13646 </para></entry>
13647 </row>
13649 <row>
13650 <entry role="func_table_entry"><para role="func_signature">
13651 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13652 <parameter>select</parameter> <type>text</type> )
13653 <returnvalue>tsquery</returnvalue>
13654 </para>
13655 <para>
13656 Replaces portions of the <parameter>query</parameter> according to
13657 target(s) and substitute(s) obtained by executing
13658 a <command>SELECT</command> command.
13659 See <xref linkend="textsearch-query-rewriting"/> for details.
13660 </para>
13661 <para>
13662 <literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal>
13663 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13664 </para></entry>
13665 </row>
13667 <row>
13668 <entry role="func_table_entry"><para role="func_signature">
13669 <indexterm>
13670 <primary>tsquery_phrase</primary>
13671 </indexterm>
13672 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type> )
13673 <returnvalue>tsquery</returnvalue>
13674 </para>
13675 <para>
13676 Constructs a phrase query that searches
13677 for matches of <parameter>query1</parameter>
13678 and <parameter>query2</parameter> at successive lexemes (same
13679 as <literal>&lt;-&gt;</literal> operator).
13680 </para>
13681 <para>
13682 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))</literal>
13683 <returnvalue>'fat' &lt;-&gt; 'cat'</returnvalue>
13684 </para></entry>
13685 </row>
13687 <row>
13688 <entry role="func_table_entry"><para role="func_signature">
13689 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type>, <parameter>distance</parameter> <type>integer</type> )
13690 <returnvalue>tsquery</returnvalue>
13691 </para>
13692 <para>
13693 Constructs a phrase query that searches
13694 for matches of <parameter>query1</parameter> and
13695 <parameter>query2</parameter> that occur exactly
13696 <parameter>distance</parameter> lexemes apart.
13697 </para>
13698 <para>
13699 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'), 10)</literal>
13700 <returnvalue>'fat' &lt;10&gt; 'cat'</returnvalue>
13701 </para></entry>
13702 </row>
13704 <row>
13705 <entry role="func_table_entry"><para role="func_signature">
13706 <indexterm>
13707 <primary>tsvector_to_array</primary>
13708 </indexterm>
13709 <function>tsvector_to_array</function> ( <type>tsvector</type> )
13710 <returnvalue>text[]</returnvalue>
13711 </para>
13712 <para>
13713 Converts a <type>tsvector</type> to an array of lexemes.
13714 </para>
13715 <para>
13716 <literal>tsvector_to_array('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13717 <returnvalue>{cat,fat,rat}</returnvalue>
13718 </para></entry>
13719 </row>
13721 <row>
13722 <entry role="func_table_entry"><para role="func_signature">
13723 <indexterm>
13724 <primary>unnest</primary>
13725 <secondary>for tsvector</secondary>
13726 </indexterm>
13727 <function>unnest</function> ( <type>tsvector</type> )
13728 <returnvalue>setof record</returnvalue>
13729 ( <parameter>lexeme</parameter> <type>text</type>,
13730 <parameter>positions</parameter> <type>smallint[]</type>,
13731 <parameter>weights</parameter> <type>text</type> )
13732 </para>
13733 <para>
13734 Expands a <type>tsvector</type> into a set of rows, one per lexeme.
13735 </para>
13736 <para>
13737 <literal>select * from unnest('cat:3 fat:2,4 rat:5A'::tsvector)</literal>
13738 <returnvalue></returnvalue>
13739 <programlisting>
13740 lexeme | positions | weights
13741 --------+-----------+---------
13742 cat | {3} | {D}
13743 fat | {2,4} | {D,D}
13744 rat | {5} | {A}
13745 </programlisting>
13746 </para></entry>
13747 </row>
13748 </tbody>
13749 </tgroup>
13750 </table>
13752 <note>
13753 <para>
13754 All the text search functions that accept an optional <type>regconfig</type>
13755 argument will use the configuration specified by
13756 <xref linkend="guc-default-text-search-config"/>
13757 when that argument is omitted.
13758 </para>
13759 </note>
13761 <para>
13762 The functions in
13763 <xref linkend="textsearch-functions-debug-table"/>
13764 are listed separately because they are not usually used in everyday text
13765 searching operations. They are primarily helpful for development and
13766 debugging of new text search configurations.
13767 </para>
13769 <table id="textsearch-functions-debug-table">
13770 <title>Text Search Debugging Functions</title>
13771 <tgroup cols="1">
13772 <thead>
13773 <row>
13774 <entry role="func_table_entry"><para role="func_signature">
13775 Function
13776 </para>
13777 <para>
13778 Description
13779 </para>
13780 <para>
13781 Example(s)
13782 </para></entry>
13783 </row>
13784 </thead>
13786 <tbody>
13787 <row>
13788 <entry role="func_table_entry"><para role="func_signature">
13789 <indexterm>
13790 <primary>ts_debug</primary>
13791 </indexterm>
13792 <function>ts_debug</function> (
13793 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13794 <parameter>document</parameter> <type>text</type> )
13795 <returnvalue>setof record</returnvalue>
13796 ( <parameter>alias</parameter> <type>text</type>,
13797 <parameter>description</parameter> <type>text</type>,
13798 <parameter>token</parameter> <type>text</type>,
13799 <parameter>dictionaries</parameter> <type>regdictionary[]</type>,
13800 <parameter>dictionary</parameter> <type>regdictionary</type>,
13801 <parameter>lexemes</parameter> <type>text[]</type> )
13802 </para>
13803 <para>
13804 Extracts and normalizes tokens from
13805 the <parameter>document</parameter> according to the specified or
13806 default text search configuration, and returns information about how
13807 each token was processed.
13808 See <xref linkend="textsearch-configuration-testing"/> for details.
13809 </para>
13810 <para>
13811 <literal>ts_debug('english', 'The Brightest supernovaes')</literal>
13812 <returnvalue>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</returnvalue>
13813 </para></entry>
13814 </row>
13816 <row>
13817 <entry role="func_table_entry"><para role="func_signature">
13818 <indexterm>
13819 <primary>ts_lexize</primary>
13820 </indexterm>
13821 <function>ts_lexize</function> ( <parameter>dict</parameter> <type>regdictionary</type>, <parameter>token</parameter> <type>text</type> )
13822 <returnvalue>text[]</returnvalue>
13823 </para>
13824 <para>
13825 Returns an array of replacement lexemes if the input token is known to
13826 the dictionary, or an empty array if the token is known to the
13827 dictionary but it is a stop word, or NULL if it is not a known word.
13828 See <xref linkend="textsearch-dictionary-testing"/> for details.
13829 </para>
13830 <para>
13831 <literal>ts_lexize('english_stem', 'stars')</literal>
13832 <returnvalue>{star}</returnvalue>
13833 </para></entry>
13834 </row>
13836 <row>
13837 <entry role="func_table_entry"><para role="func_signature">
13838 <indexterm>
13839 <primary>ts_parse</primary>
13840 </indexterm>
13841 <function>ts_parse</function> ( <parameter>parser_name</parameter> <type>text</type>,
13842 <parameter>document</parameter> <type>text</type> )
13843 <returnvalue>setof record</returnvalue>
13844 ( <parameter>tokid</parameter> <type>integer</type>,
13845 <parameter>token</parameter> <type>text</type> )
13846 </para>
13847 <para>
13848 Extracts tokens from the <parameter>document</parameter> using the
13849 named parser.
13850 See <xref linkend="textsearch-parser-testing"/> for details.
13851 </para>
13852 <para>
13853 <literal>ts_parse('default', 'foo - bar')</literal>
13854 <returnvalue>(1,foo) ...</returnvalue>
13855 </para></entry>
13856 </row>
13858 <row>
13859 <entry role="func_table_entry"><para role="func_signature">
13860 <function>ts_parse</function> ( <parameter>parser_oid</parameter> <type>oid</type>,
13861 <parameter>document</parameter> <type>text</type> )
13862 <returnvalue>setof record</returnvalue>
13863 ( <parameter>tokid</parameter> <type>integer</type>,
13864 <parameter>token</parameter> <type>text</type> )
13865 </para>
13866 <para>
13867 Extracts tokens from the <parameter>document</parameter> using a
13868 parser specified by OID.
13869 See <xref linkend="textsearch-parser-testing"/> for details.
13870 </para>
13871 <para>
13872 <literal>ts_parse(3722, 'foo - bar')</literal>
13873 <returnvalue>(1,foo) ...</returnvalue>
13874 </para></entry>
13875 </row>
13877 <row>
13878 <entry role="func_table_entry"><para role="func_signature">
13879 <indexterm>
13880 <primary>ts_token_type</primary>
13881 </indexterm>
13882 <function>ts_token_type</function> ( <parameter>parser_name</parameter> <type>text</type> )
13883 <returnvalue>setof record</returnvalue>
13884 ( <parameter>tokid</parameter> <type>integer</type>,
13885 <parameter>alias</parameter> <type>text</type>,
13886 <parameter>description</parameter> <type>text</type> )
13887 </para>
13888 <para>
13889 Returns a table that describes each type of token the named parser can
13890 recognize.
13891 See <xref linkend="textsearch-parser-testing"/> for details.
13892 </para>
13893 <para>
13894 <literal>ts_token_type('default')</literal>
13895 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
13896 </para></entry>
13897 </row>
13899 <row>
13900 <entry role="func_table_entry"><para role="func_signature">
13901 <function>ts_token_type</function> ( <parameter>parser_oid</parameter> <type>oid</type> )
13902 <returnvalue>setof record</returnvalue>
13903 ( <parameter>tokid</parameter> <type>integer</type>,
13904 <parameter>alias</parameter> <type>text</type>,
13905 <parameter>description</parameter> <type>text</type> )
13906 </para>
13907 <para>
13908 Returns a table that describes each type of token a parser specified
13909 by OID can recognize.
13910 See <xref linkend="textsearch-parser-testing"/> for details.
13911 </para>
13912 <para>
13913 <literal>ts_token_type(3722)</literal>
13914 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
13915 </para></entry>
13916 </row>
13918 <row>
13919 <entry role="func_table_entry"><para role="func_signature">
13920 <indexterm>
13921 <primary>ts_stat</primary>
13922 </indexterm>
13923 <function>ts_stat</function> ( <parameter>sqlquery</parameter> <type>text</type>
13924 <optional>, <parameter>weights</parameter> <type>text</type> </optional> )
13925 <returnvalue>setof record</returnvalue>
13926 ( <parameter>word</parameter> <type>text</type>,
13927 <parameter>ndoc</parameter> <type>integer</type>,
13928 <parameter>nentry</parameter> <type>integer</type> )
13929 </para>
13930 <para>
13931 Executes the <parameter>sqlquery</parameter>, which must return a
13932 single <type>tsvector</type> column, and returns statistics about each
13933 distinct lexeme contained in the data.
13934 See <xref linkend="textsearch-statistics"/> for details.
13935 </para>
13936 <para>
13937 <literal>ts_stat('SELECT vector FROM apod')</literal>
13938 <returnvalue>(foo,10,15) ...</returnvalue>
13939 </para></entry>
13940 </row>
13941 </tbody>
13942 </tgroup>
13943 </table>
13945 </sect1>
13947 <sect1 id="functions-uuid">
13948 <title>UUID Functions</title>
13950 <indexterm zone="datatype-uuid">
13951 <primary>UUID</primary>
13952 <secondary>generating</secondary>
13953 </indexterm>
13955 <indexterm>
13956 <primary>gen_random_uuid</primary>
13957 </indexterm>
13959 <para>
13960 <productname>PostgreSQL</productname> includes one function to generate a UUID:
13961 <synopsis>
13962 <function>gen_random_uuid</function> () <returnvalue>uuid</returnvalue>
13963 </synopsis>
13964 This function returns a version 4 (random) UUID. This is the most commonly
13965 used type of UUID and is appropriate for most applications.
13966 </para>
13968 <para>
13969 The <xref linkend="uuid-ossp"/> module provides additional functions that
13970 implement other standard algorithms for generating UUIDs.
13971 </para>
13973 <para>
13974 <productname>PostgreSQL</productname> also provides the usual comparison
13975 operators shown in <xref linkend="functions-comparison-op-table"/> for
13976 UUIDs.
13977 </para>
13978 </sect1>
13980 <sect1 id="functions-xml">
13982 <title>XML Functions</title>
13984 <indexterm>
13985 <primary>XML Functions</primary>
13986 </indexterm>
13988 <para>
13989 The functions and function-like expressions described in this
13990 section operate on values of type <type>xml</type>. See <xref
13991 linkend="datatype-xml"/> for information about the <type>xml</type>
13992 type. The function-like expressions <function>xmlparse</function>
13993 and <function>xmlserialize</function> for converting to and from
13994 type <type>xml</type> are documented there, not in this section.
13995 </para>
13997 <para>
13998 Use of most of these functions
13999 requires <productname>PostgreSQL</productname> to have been built
14000 with <command>configure --with-libxml</command>.
14001 </para>
14003 <sect2 id="functions-producing-xml">
14004 <title>Producing XML Content</title>
14006 <para>
14007 A set of functions and function-like expressions is available for
14008 producing XML content from SQL data. As such, they are
14009 particularly suitable for formatting query results into XML
14010 documents for processing in client applications.
14011 </para>
14013 <sect3 id="functions-producing-xml-xmlcomment">
14014 <title><literal>xmlcomment</literal></title>
14016 <indexterm>
14017 <primary>xmlcomment</primary>
14018 </indexterm>
14020 <synopsis>
14021 <function>xmlcomment</function> ( <type>text</type> ) <returnvalue>xml</returnvalue>
14022 </synopsis>
14024 <para>
14025 The function <function>xmlcomment</function> creates an XML value
14026 containing an XML comment with the specified text as content.
14027 The text cannot contain <quote><literal>--</literal></quote> or end with a
14028 <quote><literal>-</literal></quote>, otherwise the resulting construct
14029 would not be a valid XML comment.
14030 If the argument is null, the result is null.
14031 </para>
14033 <para>
14034 Example:
14035 <screen><![CDATA[
14036 SELECT xmlcomment('hello');
14038 xmlcomment
14039 --------------
14040 <!--hello-->
14041 ]]></screen>
14042 </para>
14043 </sect3>
14045 <sect3 id="functions-producing-xml-xmlconcat">
14046 <title><literal>xmlconcat</literal></title>
14048 <indexterm>
14049 <primary>xmlconcat</primary>
14050 </indexterm>
14052 <synopsis>
14053 <function>xmlconcat</function> ( <type>xml</type> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
14054 </synopsis>
14056 <para>
14057 The function <function>xmlconcat</function> concatenates a list
14058 of individual XML values to create a single value containing an
14059 XML content fragment. Null values are omitted; the result is
14060 only null if there are no nonnull arguments.
14061 </para>
14063 <para>
14064 Example:
14065 <screen><![CDATA[
14066 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
14068 xmlconcat
14069 ----------------------
14070 <abc/><bar>foo</bar>
14071 ]]></screen>
14072 </para>
14074 <para>
14075 XML declarations, if present, are combined as follows. If all
14076 argument values have the same XML version declaration, that
14077 version is used in the result, else no version is used. If all
14078 argument values have the standalone declaration value
14079 <quote>yes</quote>, then that value is used in the result. If
14080 all argument values have a standalone declaration value and at
14081 least one is <quote>no</quote>, then that is used in the result.
14082 Else the result will have no standalone declaration. If the
14083 result is determined to require a standalone declaration but no
14084 version declaration, a version declaration with version 1.0 will
14085 be used because XML requires an XML declaration to contain a
14086 version declaration. Encoding declarations are ignored and
14087 removed in all cases.
14088 </para>
14090 <para>
14091 Example:
14092 <screen><![CDATA[
14093 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
14095 xmlconcat
14096 -----------------------------------
14097 <?xml version="1.1"?><foo/><bar/>
14098 ]]></screen>
14099 </para>
14100 </sect3>
14102 <sect3 id="functions-producing-xml-xmlelement">
14103 <title><literal>xmlelement</literal></title>
14105 <indexterm>
14106 <primary>xmlelement</primary>
14107 </indexterm>
14109 <synopsis>
14110 <function>xmlelement</function> ( <literal>NAME</literal> <replaceable>name</replaceable> <optional>, <literal>XMLATTRIBUTES</literal> ( <replaceable>attvalue</replaceable> <optional> <literal>AS</literal> <replaceable>attname</replaceable> </optional> <optional>, ...</optional> ) </optional> <optional>, <replaceable>content</replaceable> <optional>, ...</optional></optional> ) <returnvalue>xml</returnvalue>
14111 </synopsis>
14113 <para>
14114 The <function>xmlelement</function> expression produces an XML
14115 element with the given name, attributes, and content.
14116 The <replaceable>name</replaceable>
14117 and <replaceable>attname</replaceable> items shown in the syntax are
14118 simple identifiers, not values. The <replaceable>attvalue</replaceable>
14119 and <replaceable>content</replaceable> items are expressions, which can
14120 yield any <productname>PostgreSQL</productname> data type. The
14121 argument(s) within <literal>XMLATTRIBUTES</literal> generate attributes
14122 of the XML element; the <replaceable>content</replaceable> value(s) are
14123 concatenated to form its content.
14124 </para>
14126 <para>
14127 Examples:
14128 <screen><![CDATA[
14129 SELECT xmlelement(name foo);
14131 xmlelement
14132 ------------
14133 <foo/>
14135 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
14137 xmlelement
14138 ------------------
14139 <foo bar="xyz"/>
14141 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
14143 xmlelement
14144 -------------------------------------
14145 <foo bar="2007-01-26">content</foo>
14146 ]]></screen>
14147 </para>
14149 <para>
14150 Element and attribute names that are not valid XML names are
14151 escaped by replacing the offending characters by the sequence
14152 <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
14153 <replaceable>HHHH</replaceable> is the character's Unicode
14154 codepoint in hexadecimal notation. For example:
14155 <screen><![CDATA[
14156 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
14158 xmlelement
14159 ----------------------------------
14160 <foo_x0024_bar a_x0026_b="xyz"/>
14161 ]]></screen>
14162 </para>
14164 <para>
14165 An explicit attribute name need not be specified if the attribute
14166 value is a column reference, in which case the column's name will
14167 be used as the attribute name by default. In other cases, the
14168 attribute must be given an explicit name. So this example is
14169 valid:
14170 <screen>
14171 CREATE TABLE test (a xml, b xml);
14172 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
14173 </screen>
14174 But these are not:
14175 <screen>
14176 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
14177 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
14178 </screen>
14179 </para>
14181 <para>
14182 Element content, if specified, will be formatted according to
14183 its data type. If the content is itself of type <type>xml</type>,
14184 complex XML documents can be constructed. For example:
14185 <screen><![CDATA[
14186 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
14187 xmlelement(name abc),
14188 xmlcomment('test'),
14189 xmlelement(name xyz));
14191 xmlelement
14192 ----------------------------------------------
14193 <foo bar="xyz"><abc/><!--test--><xyz/></foo>
14194 ]]></screen>
14196 Content of other types will be formatted into valid XML character
14197 data. This means in particular that the characters &lt;, &gt;,
14198 and &amp; will be converted to entities. Binary data (data type
14199 <type>bytea</type>) will be represented in base64 or hex
14200 encoding, depending on the setting of the configuration parameter
14201 <xref linkend="guc-xmlbinary"/>. The particular behavior for
14202 individual data types is expected to evolve in order to align the
14203 PostgreSQL mappings with those specified in SQL:2006 and later,
14204 as discussed in <xref linkend="functions-xml-limits-casts"/>.
14205 </para>
14206 </sect3>
14208 <sect3 id="functions-producing-xml-xmlforest">
14209 <title><literal>xmlforest</literal></title>
14211 <indexterm>
14212 <primary>xmlforest</primary>
14213 </indexterm>
14215 <synopsis>
14216 <function>xmlforest</function> ( <replaceable>content</replaceable> <optional> <literal>AS</literal> <replaceable>name</replaceable> </optional> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
14217 </synopsis>
14219 <para>
14220 The <function>xmlforest</function> expression produces an XML
14221 forest (sequence) of elements using the given names and content.
14222 As for <function>xmlelement</function>,
14223 each <replaceable>name</replaceable> must be a simple identifier, while
14224 the <replaceable>content</replaceable> expressions can have any data
14225 type.
14226 </para>
14228 <para>
14229 Examples:
14230 <screen>
14231 SELECT xmlforest('abc' AS foo, 123 AS bar);
14233 xmlforest
14234 ------------------------------
14235 &lt;foo&gt;abc&lt;/foo&gt;&lt;bar&gt;123&lt;/bar&gt;
14238 SELECT xmlforest(table_name, column_name)
14239 FROM information_schema.columns
14240 WHERE table_schema = 'pg_catalog';
14242 xmlforest
14243 ------------------------------------&zwsp;-----------------------------------
14244 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolname&lt;/column_name&gt;
14245 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolsuper&lt;/column_name&gt;
14247 </screen>
14249 As seen in the second example, the element name can be omitted if
14250 the content value is a column reference, in which case the column
14251 name is used by default. Otherwise, a name must be specified.
14252 </para>
14254 <para>
14255 Element names that are not valid XML names are escaped as shown
14256 for <function>xmlelement</function> above. Similarly, content
14257 data is escaped to make valid XML content, unless it is already
14258 of type <type>xml</type>.
14259 </para>
14261 <para>
14262 Note that XML forests are not valid XML documents if they consist
14263 of more than one element, so it might be useful to wrap
14264 <function>xmlforest</function> expressions in
14265 <function>xmlelement</function>.
14266 </para>
14267 </sect3>
14269 <sect3 id="functions-producing-xml-xmlpi">
14270 <title><literal>xmlpi</literal></title>
14272 <indexterm>
14273 <primary>xmlpi</primary>
14274 </indexterm>
14276 <synopsis>
14277 <function>xmlpi</function> ( <literal>NAME</literal> <replaceable>name</replaceable> <optional>, <replaceable>content</replaceable> </optional> ) <returnvalue>xml</returnvalue>
14278 </synopsis>
14280 <para>
14281 The <function>xmlpi</function> expression creates an XML
14282 processing instruction.
14283 As for <function>xmlelement</function>,
14284 the <replaceable>name</replaceable> must be a simple identifier, while
14285 the <replaceable>content</replaceable> expression can have any data type.
14286 The <replaceable>content</replaceable>, if present, must not contain the
14287 character sequence <literal>?&gt;</literal>.
14288 </para>
14290 <para>
14291 Example:
14292 <screen><![CDATA[
14293 SELECT xmlpi(name php, 'echo "hello world";');
14295 xmlpi
14296 -----------------------------
14297 <?php echo "hello world";?>
14298 ]]></screen>
14299 </para>
14300 </sect3>
14302 <sect3 id="functions-producing-xml-xmlroot">
14303 <title><literal>xmlroot</literal></title>
14305 <indexterm>
14306 <primary>xmlroot</primary>
14307 </indexterm>
14309 <synopsis>
14310 <function>xmlroot</function> ( <type>xml</type>, <literal>VERSION</literal> {<type>text</type>|<literal>NO VALUE</literal>} <optional>, <literal>STANDALONE</literal> {<literal>YES</literal>|<literal>NO</literal>|<literal>NO VALUE</literal>} </optional> ) <returnvalue>xml</returnvalue>
14311 </synopsis>
14313 <para>
14314 The <function>xmlroot</function> expression alters the properties
14315 of the root node of an XML value. If a version is specified,
14316 it replaces the value in the root node's version declaration; if a
14317 standalone setting is specified, it replaces the value in the
14318 root node's standalone declaration.
14319 </para>
14321 <para>
14322 <screen><![CDATA[
14323 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
14324 version '1.0', standalone yes);
14326 xmlroot
14327 ----------------------------------------
14328 <?xml version="1.0" standalone="yes"?>
14329 <content>abc</content>
14330 ]]></screen>
14331 </para>
14332 </sect3>
14334 <sect3 id="functions-xml-xmlagg">
14335 <title><literal>xmlagg</literal></title>
14337 <indexterm>
14338 <primary>xmlagg</primary>
14339 </indexterm>
14341 <synopsis>
14342 <function>xmlagg</function> ( <type>xml</type> ) <returnvalue>xml</returnvalue>
14343 </synopsis>
14345 <para>
14346 The function <function>xmlagg</function> is, unlike the other
14347 functions described here, an aggregate function. It concatenates the
14348 input values to the aggregate function call,
14349 much like <function>xmlconcat</function> does, except that concatenation
14350 occurs across rows rather than across expressions in a single row.
14351 See <xref linkend="functions-aggregate"/> for additional information
14352 about aggregate functions.
14353 </para>
14355 <para>
14356 Example:
14357 <screen><![CDATA[
14358 CREATE TABLE test (y int, x xml);
14359 INSERT INTO test VALUES (1, '<foo>abc</foo>');
14360 INSERT INTO test VALUES (2, '<bar/>');
14361 SELECT xmlagg(x) FROM test;
14362 xmlagg
14363 ----------------------
14364 <foo>abc</foo><bar/>
14365 ]]></screen>
14366 </para>
14368 <para>
14369 To determine the order of the concatenation, an <literal>ORDER BY</literal>
14370 clause may be added to the aggregate call as described in
14371 <xref linkend="syntax-aggregates"/>. For example:
14373 <screen><![CDATA[
14374 SELECT xmlagg(x ORDER BY y DESC) FROM test;
14375 xmlagg
14376 ----------------------
14377 <bar/><foo>abc</foo>
14378 ]]></screen>
14379 </para>
14381 <para>
14382 The following non-standard approach used to be recommended
14383 in previous versions, and may still be useful in specific
14384 cases:
14386 <screen><![CDATA[
14387 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
14388 xmlagg
14389 ----------------------
14390 <bar/><foo>abc</foo>
14391 ]]></screen>
14392 </para>
14393 </sect3>
14394 </sect2>
14396 <sect2 id="functions-xml-predicates">
14397 <title>XML Predicates</title>
14399 <para>
14400 The expressions described in this section check properties
14401 of <type>xml</type> values.
14402 </para>
14404 <sect3 id="functions-producing-xml-is-document">
14405 <title><literal>IS DOCUMENT</literal></title>
14407 <indexterm>
14408 <primary>IS DOCUMENT</primary>
14409 </indexterm>
14411 <synopsis>
14412 <type>xml</type> <literal>IS DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14413 </synopsis>
14415 <para>
14416 The expression <literal>IS DOCUMENT</literal> returns true if the
14417 argument XML value is a proper XML document, false if it is not
14418 (that is, it is a content fragment), or null if the argument is
14419 null. See <xref linkend="datatype-xml"/> about the difference
14420 between documents and content fragments.
14421 </para>
14422 </sect3>
14424 <sect3 id="functions-producing-xml-is-not-document">
14425 <title><literal>IS NOT DOCUMENT</literal></title>
14427 <indexterm>
14428 <primary>IS NOT DOCUMENT</primary>
14429 </indexterm>
14431 <synopsis>
14432 <type>xml</type> <literal>IS NOT DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14433 </synopsis>
14435 <para>
14436 The expression <literal>IS NOT DOCUMENT</literal> returns false if the
14437 argument XML value is a proper XML document, true if it is not (that is,
14438 it is a content fragment), or null if the argument is null.
14439 </para>
14440 </sect3>
14442 <sect3 id="xml-exists">
14443 <title><literal>XMLEXISTS</literal></title>
14445 <indexterm>
14446 <primary>XMLEXISTS</primary>
14447 </indexterm>
14449 <synopsis>
14450 <function>XMLEXISTS</function> ( <type>text</type> <literal>PASSING</literal> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional> <type>xml</type> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional> ) <returnvalue>boolean</returnvalue>
14451 </synopsis>
14453 <para>
14454 The function <function>xmlexists</function> evaluates an XPath 1.0
14455 expression (the first argument), with the passed XML value as its context
14456 item. The function returns false if the result of that evaluation
14457 yields an empty node-set, true if it yields any other value. The
14458 function returns null if any argument is null. A nonnull value
14459 passed as the context item must be an XML document, not a content
14460 fragment or any non-XML value.
14461 </para>
14463 <para>
14464 Example:
14465 <screen><![CDATA[
14466 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '<towns><town>Toronto</town><town>Ottawa</town></towns>');
14468 xmlexists
14469 ------------
14471 (1 row)
14472 ]]></screen>
14473 </para>
14475 <para>
14476 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
14477 are accepted in <productname>PostgreSQL</productname>, but are ignored,
14478 as discussed in <xref linkend="functions-xml-limits-postgresql"/>.
14479 </para>
14481 <para>
14482 In the SQL standard, the <function>xmlexists</function> function
14483 evaluates an expression in the XML Query language,
14484 but <productname>PostgreSQL</productname> allows only an XPath 1.0
14485 expression, as discussed in
14486 <xref linkend="functions-xml-limits-xpath1"/>.
14487 </para>
14488 </sect3>
14490 <sect3 id="xml-is-well-formed">
14491 <title><literal>xml_is_well_formed</literal></title>
14493 <indexterm>
14494 <primary>xml_is_well_formed</primary>
14495 </indexterm>
14497 <indexterm>
14498 <primary>xml_is_well_formed_document</primary>
14499 </indexterm>
14501 <indexterm>
14502 <primary>xml_is_well_formed_content</primary>
14503 </indexterm>
14505 <synopsis>
14506 <function>xml_is_well_formed</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14507 <function>xml_is_well_formed_document</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14508 <function>xml_is_well_formed_content</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14509 </synopsis>
14511 <para>
14512 These functions check whether a <type>text</type> string represents
14513 well-formed XML, returning a Boolean result.
14514 <function>xml_is_well_formed_document</function> checks for a well-formed
14515 document, while <function>xml_is_well_formed_content</function> checks
14516 for well-formed content. <function>xml_is_well_formed</function> does
14517 the former if the <xref linkend="guc-xmloption"/> configuration
14518 parameter is set to <literal>DOCUMENT</literal>, or the latter if it is set to
14519 <literal>CONTENT</literal>. This means that
14520 <function>xml_is_well_formed</function> is useful for seeing whether
14521 a simple cast to type <type>xml</type> will succeed, whereas the other two
14522 functions are useful for seeing whether the corresponding variants of
14523 <function>XMLPARSE</function> will succeed.
14524 </para>
14526 <para>
14527 Examples:
14529 <screen><![CDATA[
14530 SET xmloption TO DOCUMENT;
14531 SELECT xml_is_well_formed('<>');
14532 xml_is_well_formed
14533 --------------------
14535 (1 row)
14537 SELECT xml_is_well_formed('<abc/>');
14538 xml_is_well_formed
14539 --------------------
14541 (1 row)
14543 SET xmloption TO CONTENT;
14544 SELECT xml_is_well_formed('abc');
14545 xml_is_well_formed
14546 --------------------
14548 (1 row)
14550 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
14551 xml_is_well_formed_document
14552 -----------------------------
14554 (1 row)
14556 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
14557 xml_is_well_formed_document
14558 -----------------------------
14560 (1 row)
14561 ]]></screen>
14563 The last example shows that the checks include whether
14564 namespaces are correctly matched.
14565 </para>
14566 </sect3>
14567 </sect2>
14569 <sect2 id="functions-xml-processing">
14570 <title>Processing XML</title>
14572 <para>
14573 To process values of data type <type>xml</type>, PostgreSQL offers
14574 the functions <function>xpath</function> and
14575 <function>xpath_exists</function>, which evaluate XPath 1.0
14576 expressions, and the <function>XMLTABLE</function>
14577 table function.
14578 </para>
14580 <sect3 id="functions-xml-processing-xpath">
14581 <title><literal>xpath</literal></title>
14583 <indexterm>
14584 <primary>XPath</primary>
14585 </indexterm>
14587 <synopsis>
14588 <function>xpath</function> ( <parameter>xpath</parameter> <type>text</type>, <parameter>xml</parameter> <type>xml</type> <optional>, <parameter>nsarray</parameter> <type>text[]</type> </optional> ) <returnvalue>xml[]</returnvalue>
14589 </synopsis>
14591 <para>
14592 The function <function>xpath</function> evaluates the XPath 1.0
14593 expression <parameter>xpath</parameter> (given as text)
14594 against the XML value
14595 <parameter>xml</parameter>. It returns an array of XML values
14596 corresponding to the node-set produced by the XPath expression.
14597 If the XPath expression returns a scalar value rather than a node-set,
14598 a single-element array is returned.
14599 </para>
14601 <para>
14602 The second argument must be a well formed XML document. In particular,
14603 it must have a single root node element.
14604 </para>
14606 <para>
14607 The optional third argument of the function is an array of namespace
14608 mappings. This array should be a two-dimensional <type>text</type> array with
14609 the length of the second axis being equal to 2 (i.e., it should be an
14610 array of arrays, each of which consists of exactly 2 elements).
14611 The first element of each array entry is the namespace name (alias), the
14612 second the namespace URI. It is not required that aliases provided in
14613 this array be the same as those being used in the XML document itself (in
14614 other words, both in the XML document and in the <function>xpath</function>
14615 function context, aliases are <emphasis>local</emphasis>).
14616 </para>
14618 <para>
14619 Example:
14620 <screen><![CDATA[
14621 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
14622 ARRAY[ARRAY['my', 'http://example.com']]);
14624 xpath
14625 --------
14626 {test}
14627 (1 row)
14628 ]]></screen>
14629 </para>
14631 <para>
14632 To deal with default (anonymous) namespaces, do something like this:
14633 <screen><![CDATA[
14634 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
14635 ARRAY[ARRAY['mydefns', 'http://example.com']]);
14637 xpath
14638 --------
14639 {test}
14640 (1 row)
14641 ]]></screen>
14642 </para>
14643 </sect3>
14645 <sect3 id="functions-xml-processing-xpath-exists">
14646 <title><literal>xpath_exists</literal></title>
14648 <indexterm>
14649 <primary>xpath_exists</primary>
14650 </indexterm>
14652 <synopsis>
14653 <function>xpath_exists</function> ( <parameter>xpath</parameter> <type>text</type>, <parameter>xml</parameter> <type>xml</type> <optional>, <parameter>nsarray</parameter> <type>text[]</type> </optional> ) <returnvalue>boolean</returnvalue>
14654 </synopsis>
14656 <para>
14657 The function <function>xpath_exists</function> is a specialized form
14658 of the <function>xpath</function> function. Instead of returning the
14659 individual XML values that satisfy the XPath 1.0 expression, this function
14660 returns a Boolean indicating whether the query was satisfied or not
14661 (specifically, whether it produced any value other than an empty node-set).
14662 This function is equivalent to the <literal>XMLEXISTS</literal> predicate,
14663 except that it also offers support for a namespace mapping argument.
14664 </para>
14666 <para>
14667 Example:
14668 <screen><![CDATA[
14669 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
14670 ARRAY[ARRAY['my', 'http://example.com']]);
14672 xpath_exists
14673 --------------
14675 (1 row)
14676 ]]></screen>
14677 </para>
14678 </sect3>
14680 <sect3 id="functions-xml-processing-xmltable">
14681 <title><literal>xmltable</literal></title>
14683 <indexterm>
14684 <primary>xmltable</primary>
14685 </indexterm>
14687 <indexterm zone="functions-xml-processing-xmltable">
14688 <primary>table function</primary>
14689 <secondary>XMLTABLE</secondary>
14690 </indexterm>
14692 <synopsis>
14693 <function>XMLTABLE</function> (
14694 <optional> <literal>XMLNAMESPACES</literal> ( <replaceable>namespace_uri</replaceable> <literal>AS</literal> <replaceable>namespace_name</replaceable> <optional>, ...</optional> ), </optional>
14695 <replaceable>row_expression</replaceable> <literal>PASSING</literal> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional> <replaceable>document_expression</replaceable> <optional><literal>BY</literal> {<literal>REF</literal>|<literal>VALUE</literal>}</optional>
14696 <literal>COLUMNS</literal> <replaceable>name</replaceable> { <replaceable>type</replaceable> <optional><literal>PATH</literal> <replaceable>column_expression</replaceable></optional> <optional><literal>DEFAULT</literal> <replaceable>default_expression</replaceable></optional> <optional><literal>NOT NULL</literal> | <literal>NULL</literal></optional>
14697 | <literal>FOR ORDINALITY</literal> }
14698 <optional>, ...</optional>
14699 ) <returnvalue>setof record</returnvalue>
14700 </synopsis>
14702 <para>
14703 The <function>xmltable</function> expression produces a table based
14704 on an XML value, an XPath filter to extract rows, and a
14705 set of column definitions.
14706 Although it syntactically resembles a function, it can only appear
14707 as a table in a query's <literal>FROM</literal> clause.
14708 </para>
14710 <para>
14711 The optional <literal>XMLNAMESPACES</literal> clause gives a
14712 comma-separated list of namespace definitions, where
14713 each <replaceable>namespace_uri</replaceable> is a <type>text</type>
14714 expression and each <replaceable>namespace_name</replaceable> is a simple
14715 identifier. It specifies the XML namespaces used in the document and
14716 their aliases. A default namespace specification is not currently
14717 supported.
14718 </para>
14720 <para>
14721 The required <replaceable>row_expression</replaceable> argument is an
14722 XPath 1.0 expression (given as <type>text</type>) that is evaluated,
14723 passing the XML value <replaceable>document_expression</replaceable> as
14724 its context item, to obtain a set of XML nodes. These nodes are what
14725 <function>xmltable</function> transforms into output rows. No rows
14726 will be produced if the <replaceable>document_expression</replaceable>
14727 is null, nor if the <replaceable>row_expression</replaceable> produces
14728 an empty node-set or any value other than a node-set.
14729 </para>
14731 <para>
14732 <replaceable>document_expression</replaceable> provides the context
14733 item for the <replaceable>row_expression</replaceable>. It must be a
14734 well-formed XML document; fragments/forests are not accepted.
14735 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
14736 are accepted but ignored, as discussed in
14737 <xref linkend="functions-xml-limits-postgresql"/>.
14738 </para>
14740 <para>
14741 In the SQL standard, the <function>xmltable</function> function
14742 evaluates expressions in the XML Query language,
14743 but <productname>PostgreSQL</productname> allows only XPath 1.0
14744 expressions, as discussed in
14745 <xref linkend="functions-xml-limits-xpath1"/>.
14746 </para>
14748 <para>
14749 The required <literal>COLUMNS</literal> clause specifies the
14750 column(s) that will be produced in the output table.
14751 See the syntax summary above for the format.
14752 A name is required for each column, as is a data type
14753 (unless <literal>FOR ORDINALITY</literal> is specified, in which case
14754 type <type>integer</type> is implicit). The path, default and
14755 nullability clauses are optional.
14756 </para>
14758 <para>
14759 A column marked <literal>FOR ORDINALITY</literal> will be populated
14760 with row numbers, starting with 1, in the order of nodes retrieved from
14761 the <replaceable>row_expression</replaceable>'s result node-set.
14762 At most one column may be marked <literal>FOR ORDINALITY</literal>.
14763 </para>
14765 <note>
14766 <para>
14767 XPath 1.0 does not specify an order for nodes in a node-set, so code
14768 that relies on a particular order of the results will be
14769 implementation-dependent. Details can be found in
14770 <xref linkend="xml-xpath-1-specifics"/>.
14771 </para>
14772 </note>
14774 <para>
14775 The <replaceable>column_expression</replaceable> for a column is an
14776 XPath 1.0 expression that is evaluated for each row, with the current
14777 node from the <replaceable>row_expression</replaceable> result as its
14778 context item, to find the value of the column. If
14779 no <replaceable>column_expression</replaceable> is given, then the
14780 column name is used as an implicit path.
14781 </para>
14783 <para>
14784 If a column's XPath expression returns a non-XML value (which is limited
14785 to string, boolean, or double in XPath 1.0) and the column has a
14786 PostgreSQL type other than <type>xml</type>, the column will be set
14787 as if by assigning the value's string representation to the PostgreSQL
14788 type. (If the value is a boolean, its string representation is taken
14789 to be <literal>1</literal> or <literal>0</literal> if the output
14790 column's type category is numeric, otherwise <literal>true</literal> or
14791 <literal>false</literal>.)
14792 </para>
14794 <para>
14795 If a column's XPath expression returns a non-empty set of XML nodes
14796 and the column's PostgreSQL type is <type>xml</type>, the column will
14797 be assigned the expression result exactly, if it is of document or
14798 content form.
14799 <footnote>
14800 <para>
14801 A result containing more than one element node at the top level, or
14802 non-whitespace text outside of an element, is an example of content form.
14803 An XPath result can be of neither form, for example if it returns an
14804 attribute node selected from the element that contains it. Such a result
14805 will be put into content form with each such disallowed node replaced by
14806 its string value, as defined for the XPath 1.0
14807 <function>string</function> function.
14808 </para>
14809 </footnote>
14810 </para>
14812 <para>
14813 A non-XML result assigned to an <type>xml</type> output column produces
14814 content, a single text node with the string value of the result.
14815 An XML result assigned to a column of any other type may not have more than
14816 one node, or an error is raised. If there is exactly one node, the column
14817 will be set as if by assigning the node's string
14818 value (as defined for the XPath 1.0 <function>string</function> function)
14819 to the PostgreSQL type.
14820 </para>
14822 <para>
14823 The string value of an XML element is the concatenation, in document order,
14824 of all text nodes contained in that element and its descendants. The string
14825 value of an element with no descendant text nodes is an
14826 empty string (not <literal>NULL</literal>).
14827 Any <literal>xsi:nil</literal> attributes are ignored.
14828 Note that the whitespace-only <literal>text()</literal> node between two non-text
14829 elements is preserved, and that leading whitespace on a <literal>text()</literal>
14830 node is not flattened.
14831 The XPath 1.0 <function>string</function> function may be consulted for the
14832 rules defining the string value of other XML node types and non-XML values.
14833 </para>
14835 <para>
14836 The conversion rules presented here are not exactly those of the SQL
14837 standard, as discussed in <xref linkend="functions-xml-limits-casts"/>.
14838 </para>
14840 <para>
14841 If the path expression returns an empty node-set
14842 (typically, when it does not match)
14843 for a given row, the column will be set to <literal>NULL</literal>, unless
14844 a <replaceable>default_expression</replaceable> is specified; then the
14845 value resulting from evaluating that expression is used.
14846 </para>
14848 <para>
14849 A <replaceable>default_expression</replaceable>, rather than being
14850 evaluated immediately when <function>xmltable</function> is called,
14851 is evaluated each time a default is needed for the column.
14852 If the expression qualifies as stable or immutable, the repeat
14853 evaluation may be skipped.
14854 This means that you can usefully use volatile functions like
14855 <function>nextval</function> in
14856 <replaceable>default_expression</replaceable>.
14857 </para>
14859 <para>
14860 Columns may be marked <literal>NOT NULL</literal>. If the
14861 <replaceable>column_expression</replaceable> for a <literal>NOT
14862 NULL</literal> column does not match anything and there is
14863 no <literal>DEFAULT</literal> or
14864 the <replaceable>default_expression</replaceable> also evaluates to null,
14865 an error is reported.
14866 </para>
14868 <para>
14869 Examples:
14870 <screen><![CDATA[
14871 CREATE TABLE xmldata AS SELECT
14872 xml $$
14873 <ROWS>
14874 <ROW id="1">
14875 <COUNTRY_ID>AU</COUNTRY_ID>
14876 <COUNTRY_NAME>Australia</COUNTRY_NAME>
14877 </ROW>
14878 <ROW id="5">
14879 <COUNTRY_ID>JP</COUNTRY_ID>
14880 <COUNTRY_NAME>Japan</COUNTRY_NAME>
14881 <PREMIER_NAME>Shinzo Abe</PREMIER_NAME>
14882 <SIZE unit="sq_mi">145935</SIZE>
14883 </ROW>
14884 <ROW id="6">
14885 <COUNTRY_ID>SG</COUNTRY_ID>
14886 <COUNTRY_NAME>Singapore</COUNTRY_NAME>
14887 <SIZE unit="sq_km">697</SIZE>
14888 </ROW>
14889 </ROWS>
14890 $$ AS data;
14892 SELECT xmltable.*
14893 FROM xmldata,
14894 XMLTABLE('//ROWS/ROW'
14895 PASSING data
14896 COLUMNS id int PATH '@id',
14897 ordinality FOR ORDINALITY,
14898 "COUNTRY_NAME" text,
14899 country_id text PATH 'COUNTRY_ID',
14900 size_sq_km float PATH 'SIZE[@unit = "sq_km"]',
14901 size_other text PATH
14902 'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)',
14903 premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified');
14905 id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
14906 ----+------------+--------------+------------+------------+--------------+---------------
14907 1 | 1 | Australia | AU | | | not specified
14908 5 | 2 | Japan | JP | | 145935 sq_mi | Shinzo Abe
14909 6 | 3 | Singapore | SG | 697 | | not specified
14910 ]]></screen>
14912 The following example shows concatenation of multiple text() nodes,
14913 usage of the column name as XPath filter, and the treatment of whitespace,
14914 XML comments and processing instructions:
14916 <screen><![CDATA[
14917 CREATE TABLE xmlelements AS SELECT
14918 xml $$
14919 <root>
14920 <element> Hello<!-- xyxxz -->2a2<?aaaaa?> <!--x--> bbb<x>xxx</x>CC </element>
14921 </root>
14922 $$ AS data;
14924 SELECT xmltable.*
14925 FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
14926 element
14927 -------------------------
14928 Hello2a2 bbbxxxCC
14929 ]]></screen>
14930 </para>
14932 <para>
14933 The following example illustrates how
14934 the <literal>XMLNAMESPACES</literal> clause can be used to specify
14935 a list of namespaces
14936 used in the XML document as well as in the XPath expressions:
14938 <screen><![CDATA[
14939 WITH xmldata(data) AS (VALUES ('
14940 <example xmlns="http://example.com/myns" xmlns:B="http://example.com/b">
14941 <item foo="1" B:bar="2"/>
14942 <item foo="3" B:bar="4"/>
14943 <item foo="4" B:bar="5"/>
14944 </example>'::xml)
14946 SELECT xmltable.*
14947 FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
14948 'http://example.com/b' AS "B"),
14949 '/x:example/x:item'
14950 PASSING (SELECT data FROM xmldata)
14951 COLUMNS foo int PATH '@foo',
14952 bar int PATH '@B:bar');
14953 foo | bar
14954 -----+-----
14955 1 | 2
14956 3 | 4
14957 4 | 5
14958 (3 rows)
14959 ]]></screen>
14960 </para>
14961 </sect3>
14962 </sect2>
14964 <sect2 id="functions-xml-mapping">
14965 <title>Mapping Tables to XML</title>
14967 <indexterm zone="functions-xml-mapping">
14968 <primary>XML export</primary>
14969 </indexterm>
14971 <para>
14972 The following functions map the contents of relational tables to
14973 XML values. They can be thought of as XML export functionality:
14974 <synopsis>
14975 <function>table_to_xml</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
14976 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14977 <function>query_to_xml</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
14978 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14979 <function>cursor_to_xml</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>count</parameter> <type>integer</type>, <parameter>nulls</parameter> <type>boolean</type>,
14980 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14981 </synopsis>
14982 </para>
14984 <para>
14985 <function>table_to_xml</function> maps the content of the named
14986 table, passed as parameter <parameter>table</parameter>. The
14987 <type>regclass</type> type accepts strings identifying tables using the
14988 usual notation, including optional schema qualification and
14989 double quotes (see <xref linkend="datatype-oid"/> for details).
14990 <function>query_to_xml</function> executes the
14991 query whose text is passed as parameter
14992 <parameter>query</parameter> and maps the result set.
14993 <function>cursor_to_xml</function> fetches the indicated number of
14994 rows from the cursor specified by the parameter
14995 <parameter>cursor</parameter>. This variant is recommended if
14996 large tables have to be mapped, because the result value is built
14997 up in memory by each function.
14998 </para>
15000 <para>
15001 If <parameter>tableforest</parameter> is false, then the resulting
15002 XML document looks like this:
15003 <screen><![CDATA[
15004 <tablename>
15005 <row>
15006 <columnname1>data</columnname1>
15007 <columnname2>data</columnname2>
15008 </row>
15010 <row>
15012 </row>
15015 </tablename>
15016 ]]></screen>
15018 If <parameter>tableforest</parameter> is true, the result is an
15019 XML content fragment that looks like this:
15020 <screen><![CDATA[
15021 <tablename>
15022 <columnname1>data</columnname1>
15023 <columnname2>data</columnname2>
15024 </tablename>
15026 <tablename>
15028 </tablename>
15031 ]]></screen>
15033 If no table name is available, that is, when mapping a query or a
15034 cursor, the string <literal>table</literal> is used in the first
15035 format, <literal>row</literal> in the second format.
15036 </para>
15038 <para>
15039 The choice between these formats is up to the user. The first
15040 format is a proper XML document, which will be important in many
15041 applications. The second format tends to be more useful in the
15042 <function>cursor_to_xml</function> function if the result values are to be
15043 reassembled into one document later on. The functions for
15044 producing XML content discussed above, in particular
15045 <function>xmlelement</function>, can be used to alter the results
15046 to taste.
15047 </para>
15049 <para>
15050 The data values are mapped in the same way as described for the
15051 function <function>xmlelement</function> above.
15052 </para>
15054 <para>
15055 The parameter <parameter>nulls</parameter> determines whether null
15056 values should be included in the output. If true, null values in
15057 columns are represented as:
15058 <screen><![CDATA[
15059 <columnname xsi:nil="true"/>
15060 ]]></screen>
15061 where <literal>xsi</literal> is the XML namespace prefix for XML
15062 Schema Instance. An appropriate namespace declaration will be
15063 added to the result value. If false, columns containing null
15064 values are simply omitted from the output.
15065 </para>
15067 <para>
15068 The parameter <parameter>targetns</parameter> specifies the
15069 desired XML namespace of the result. If no particular namespace
15070 is wanted, an empty string should be passed.
15071 </para>
15073 <para>
15074 The following functions return XML Schema documents describing the
15075 mappings performed by the corresponding functions above:
15076 <synopsis>
15077 <function>table_to_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15078 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15079 <function>query_to_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15080 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15081 <function>cursor_to_xmlschema</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>nulls</parameter> <type>boolean</type>,
15082 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15083 </synopsis>
15084 It is essential that the same parameters are passed in order to
15085 obtain matching XML data mappings and XML Schema documents.
15086 </para>
15088 <para>
15089 The following functions produce XML data mappings and the
15090 corresponding XML Schema in one document (or forest), linked
15091 together. They can be useful where self-contained and
15092 self-describing results are wanted:
15093 <synopsis>
15094 <function>table_to_xml_and_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15095 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15096 <function>query_to_xml_and_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15097 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15098 </synopsis>
15099 </para>
15101 <para>
15102 In addition, the following functions are available to produce
15103 analogous mappings of entire schemas or the entire current
15104 database:
15105 <synopsis>
15106 <function>schema_to_xml</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15107 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15108 <function>schema_to_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15109 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15110 <function>schema_to_xml_and_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15111 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15113 <function>database_to_xml</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15114 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15115 <function>database_to_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15116 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15117 <function>database_to_xml_and_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15118 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15119 </synopsis>
15121 These functions ignore tables that are not readable by the current user.
15122 The database-wide functions additionally ignore schemas that the current
15123 user does not have <literal>USAGE</literal> (lookup) privilege for.
15124 </para>
15126 <para>
15127 Note that these potentially produce a lot of data, which needs to
15128 be built up in memory. When requesting content mappings of large
15129 schemas or databases, it might be worthwhile to consider mapping the
15130 tables separately instead, possibly even through a cursor.
15131 </para>
15133 <para>
15134 The result of a schema content mapping looks like this:
15136 <screen><![CDATA[
15137 <schemaname>
15139 table1-mapping
15141 table2-mapping
15145 </schemaname>]]></screen>
15147 where the format of a table mapping depends on the
15148 <parameter>tableforest</parameter> parameter as explained above.
15149 </para>
15151 <para>
15152 The result of a database content mapping looks like this:
15154 <screen><![CDATA[
15155 <dbname>
15157 <schema1name>
15159 </schema1name>
15161 <schema2name>
15163 </schema2name>
15167 </dbname>]]></screen>
15169 where the schema mapping is as above.
15170 </para>
15172 <para>
15173 As an example of using the output produced by these functions,
15174 <xref linkend="xslt-xml-html"/> shows an XSLT stylesheet that
15175 converts the output of
15176 <function>table_to_xml_and_xmlschema</function> to an HTML
15177 document containing a tabular rendition of the table data. In a
15178 similar manner, the results from these functions can be
15179 converted into other XML-based formats.
15180 </para>
15182 <example id="xslt-xml-html">
15183 <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
15184 <programlisting><![CDATA[
15185 <?xml version="1.0"?>
15186 <xsl:stylesheet version="1.0"
15187 xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
15188 xmlns:xsd="http://www.w3.org/2001/XMLSchema"
15189 xmlns="http://www.w3.org/1999/xhtml"
15192 <xsl:output method="xml"
15193 doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
15194 doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
15195 indent="yes"/>
15197 <xsl:template match="/*">
15198 <xsl:variable name="schema" select="//xsd:schema"/>
15199 <xsl:variable name="tabletypename"
15200 select="$schema/xsd:element[@name=name(current())]/@type"/>
15201 <xsl:variable name="rowtypename"
15202 select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
15204 <html>
15205 <head>
15206 <title><xsl:value-of select="name(current())"/></title>
15207 </head>
15208 <body>
15209 <table>
15210 <tr>
15211 <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
15212 <th><xsl:value-of select="."/></th>
15213 </xsl:for-each>
15214 </tr>
15216 <xsl:for-each select="row">
15217 <tr>
15218 <xsl:for-each select="*">
15219 <td><xsl:value-of select="."/></td>
15220 </xsl:for-each>
15221 </tr>
15222 </xsl:for-each>
15223 </table>
15224 </body>
15225 </html>
15226 </xsl:template>
15228 </xsl:stylesheet>
15229 ]]></programlisting>
15230 </example>
15231 </sect2>
15232 </sect1>
15234 <sect1 id="functions-json">
15235 <title>JSON Functions and Operators</title>
15237 <indexterm zone="functions-json">
15238 <primary>JSON</primary>
15239 <secondary>functions and operators</secondary>
15240 </indexterm>
15241 <indexterm zone="functions-json">
15242 <primary>SQL/JSON</primary>
15243 <secondary>functions and expressions</secondary>
15244 </indexterm>
15246 <para>
15247 This section describes:
15249 <itemizedlist>
15250 <listitem>
15251 <para>
15252 functions and operators for processing and creating JSON data
15253 </para>
15254 </listitem>
15255 <listitem>
15256 <para>
15257 the SQL/JSON path language
15258 </para>
15259 </listitem>
15260 </itemizedlist>
15261 </para>
15263 <para>
15264 To provide native support for JSON data types within the SQL environment,
15265 <productname>PostgreSQL</productname> implements the
15266 <firstterm>SQL/JSON data model</firstterm>.
15267 This model comprises sequences of items. Each item can hold SQL scalar
15268 values, with an additional SQL/JSON null value, and composite data structures
15269 that use JSON arrays and objects. The model is a formalization of the implied
15270 data model in the JSON specification
15271 <ulink url="https://datatracker.ietf.org/doc/html/rfc7159">RFC 7159</ulink>.
15272 </para>
15274 <para>
15275 SQL/JSON allows you to handle JSON data alongside regular SQL data,
15276 with transaction support, including:
15278 <itemizedlist>
15279 <listitem>
15280 <para>
15281 Uploading JSON data into the database and storing it in
15282 regular SQL columns as character or binary strings.
15283 </para>
15284 </listitem>
15285 <listitem>
15286 <para>
15287 Generating JSON objects and arrays from relational data.
15288 </para>
15289 </listitem>
15290 <listitem>
15291 <para>
15292 Querying JSON data using SQL/JSON query functions and
15293 SQL/JSON path language expressions.
15294 </para>
15295 </listitem>
15296 </itemizedlist>
15297 </para>
15299 <para>
15300 To learn more about the SQL/JSON standard, see
15301 <xref linkend="sqltr-19075-6"/>. For details on JSON types
15302 supported in <productname>PostgreSQL</productname>,
15303 see <xref linkend="datatype-json"/>.
15304 </para>
15306 <sect2 id="functions-json-processing">
15307 <title>Processing and Creating JSON Data</title>
15309 <para>
15310 <xref linkend="functions-json-op-table"/> shows the operators that
15311 are available for use with JSON data types (see <xref
15312 linkend="datatype-json"/>).
15313 In addition, the usual comparison operators shown in <xref
15314 linkend="functions-comparison-op-table"/> are available for
15315 <type>jsonb</type>, though not for <type>json</type>. The comparison
15316 operators follow the ordering rules for B-tree operations outlined in
15317 <xref linkend="json-indexing"/>.
15318 See also <xref linkend="functions-aggregate"/> for the aggregate
15319 function <function>json_agg</function> which aggregates record
15320 values as JSON, the aggregate function
15321 <function>json_object_agg</function> which aggregates pairs of values
15322 into a JSON object, and their <type>jsonb</type> equivalents,
15323 <function>jsonb_agg</function> and <function>jsonb_object_agg</function>.
15324 </para>
15326 <table id="functions-json-op-table">
15327 <title><type>json</type> and <type>jsonb</type> Operators</title>
15328 <tgroup cols="1">
15329 <thead>
15330 <row>
15331 <entry role="func_table_entry"><para role="func_signature">
15332 Operator
15333 </para>
15334 <para>
15335 Description
15336 </para>
15337 <para>
15338 Example(s)
15339 </para></entry>
15340 </row>
15341 </thead>
15343 <tbody>
15344 <row>
15345 <entry role="func_table_entry"><para role="func_signature">
15346 <type>json</type> <literal>-&gt;</literal> <type>integer</type>
15347 <returnvalue>json</returnvalue>
15348 </para>
15349 <para role="func_signature">
15350 <type>jsonb</type> <literal>-&gt;</literal> <type>integer</type>
15351 <returnvalue>jsonb</returnvalue>
15352 </para>
15353 <para>
15354 Extracts <parameter>n</parameter>'th element of JSON array
15355 (array elements are indexed from zero, but negative integers count
15356 from the end).
15357 </para>
15358 <para>
15359 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; 2</literal>
15360 <returnvalue>{"c":"baz"}</returnvalue>
15361 </para>
15362 <para>
15363 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; -3</literal>
15364 <returnvalue>{"a":"foo"}</returnvalue>
15365 </para></entry>
15366 </row>
15368 <row>
15369 <entry role="func_table_entry"><para role="func_signature">
15370 <type>json</type> <literal>-&gt;</literal> <type>text</type>
15371 <returnvalue>json</returnvalue>
15372 </para>
15373 <para role="func_signature">
15374 <type>jsonb</type> <literal>-&gt;</literal> <type>text</type>
15375 <returnvalue>jsonb</returnvalue>
15376 </para>
15377 <para>
15378 Extracts JSON object field with the given key.
15379 </para>
15380 <para>
15381 <literal>'{"a": {"b":"foo"}}'::json -&gt; 'a'</literal>
15382 <returnvalue>{"b":"foo"}</returnvalue>
15383 </para></entry>
15384 </row>
15386 <row>
15387 <entry role="func_table_entry"><para role="func_signature">
15388 <type>json</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15389 <returnvalue>text</returnvalue>
15390 </para>
15391 <para role="func_signature">
15392 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15393 <returnvalue>text</returnvalue>
15394 </para>
15395 <para>
15396 Extracts <parameter>n</parameter>'th element of JSON array,
15397 as <type>text</type>.
15398 </para>
15399 <para>
15400 <literal>'[1,2,3]'::json -&gt;&gt; 2</literal>
15401 <returnvalue>3</returnvalue>
15402 </para></entry>
15403 </row>
15405 <row>
15406 <entry role="func_table_entry"><para role="func_signature">
15407 <type>json</type> <literal>-&gt;&gt;</literal> <type>text</type>
15408 <returnvalue>text</returnvalue>
15409 </para>
15410 <para role="func_signature">
15411 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>text</type>
15412 <returnvalue>text</returnvalue>
15413 </para>
15414 <para>
15415 Extracts JSON object field with the given key, as <type>text</type>.
15416 </para>
15417 <para>
15418 <literal>'{"a":1,"b":2}'::json -&gt;&gt; 'b'</literal>
15419 <returnvalue>2</returnvalue>
15420 </para></entry>
15421 </row>
15423 <row>
15424 <entry role="func_table_entry"><para role="func_signature">
15425 <type>json</type> <literal>#&gt;</literal> <type>text[]</type>
15426 <returnvalue>json</returnvalue>
15427 </para>
15428 <para role="func_signature">
15429 <type>jsonb</type> <literal>#&gt;</literal> <type>text[]</type>
15430 <returnvalue>jsonb</returnvalue>
15431 </para>
15432 <para>
15433 Extracts JSON sub-object at the specified path, where path elements
15434 can be either field keys or array indexes.
15435 </para>
15436 <para>
15437 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt; '{a,b,1}'</literal>
15438 <returnvalue>"bar"</returnvalue>
15439 </para></entry>
15440 </row>
15442 <row>
15443 <entry role="func_table_entry"><para role="func_signature">
15444 <type>json</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15445 <returnvalue>text</returnvalue>
15446 </para>
15447 <para role="func_signature">
15448 <type>jsonb</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15449 <returnvalue>text</returnvalue>
15450 </para>
15451 <para>
15452 Extracts JSON sub-object at the specified path as <type>text</type>.
15453 </para>
15454 <para>
15455 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt;&gt; '{a,b,1}'</literal>
15456 <returnvalue>bar</returnvalue>
15457 </para></entry>
15458 </row>
15459 </tbody>
15460 </tgroup>
15461 </table>
15463 <note>
15464 <para>
15465 The field/element/path extraction operators return NULL, rather than
15466 failing, if the JSON input does not have the right structure to match
15467 the request; for example if no such key or array element exists.
15468 </para>
15469 </note>
15471 <para>
15472 Some further operators exist only for <type>jsonb</type>, as shown
15473 in <xref linkend="functions-jsonb-op-table"/>.
15474 <xref linkend="json-indexing"/>
15475 describes how these operators can be used to effectively search indexed
15476 <type>jsonb</type> data.
15477 </para>
15479 <table id="functions-jsonb-op-table">
15480 <title>Additional <type>jsonb</type> Operators</title>
15481 <tgroup cols="1">
15482 <thead>
15483 <row>
15484 <entry role="func_table_entry"><para role="func_signature">
15485 Operator
15486 </para>
15487 <para>
15488 Description
15489 </para>
15490 <para>
15491 Example(s)
15492 </para></entry>
15493 </row>
15494 </thead>
15496 <tbody>
15497 <row>
15498 <entry role="func_table_entry"><para role="func_signature">
15499 <type>jsonb</type> <literal>@&gt;</literal> <type>jsonb</type>
15500 <returnvalue>boolean</returnvalue>
15501 </para>
15502 <para>
15503 Does the first JSON value contain the second?
15504 (See <xref linkend="json-containment"/> for details about containment.)
15505 </para>
15506 <para>
15507 <literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal>
15508 <returnvalue>t</returnvalue>
15509 </para></entry>
15510 </row>
15512 <row>
15513 <entry role="func_table_entry"><para role="func_signature">
15514 <type>jsonb</type> <literal>&lt;@</literal> <type>jsonb</type>
15515 <returnvalue>boolean</returnvalue>
15516 </para>
15517 <para>
15518 Is the first JSON value contained in the second?
15519 </para>
15520 <para>
15521 <literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal>
15522 <returnvalue>t</returnvalue>
15523 </para></entry>
15524 </row>
15526 <row>
15527 <entry role="func_table_entry"><para role="func_signature">
15528 <type>jsonb</type> <literal>?</literal> <type>text</type>
15529 <returnvalue>boolean</returnvalue>
15530 </para>
15531 <para>
15532 Does the text string exist as a top-level key or array element within
15533 the JSON value?
15534 </para>
15535 <para>
15536 <literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal>
15537 <returnvalue>t</returnvalue>
15538 </para>
15539 <para>
15540 <literal>'["a", "b", "c"]'::jsonb ? 'b'</literal>
15541 <returnvalue>t</returnvalue>
15542 </para></entry>
15543 </row>
15545 <row>
15546 <entry role="func_table_entry"><para role="func_signature">
15547 <type>jsonb</type> <literal>?|</literal> <type>text[]</type>
15548 <returnvalue>boolean</returnvalue>
15549 </para>
15550 <para>
15551 Do any of the strings in the text array exist as top-level keys or
15552 array elements?
15553 </para>
15554 <para>
15555 <literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'd']</literal>
15556 <returnvalue>t</returnvalue>
15557 </para></entry>
15558 </row>
15560 <row>
15561 <entry role="func_table_entry"><para role="func_signature">
15562 <type>jsonb</type> <literal>?&amp;</literal> <type>text[]</type>
15563 <returnvalue>boolean</returnvalue>
15564 </para>
15565 <para>
15566 Do all of the strings in the text array exist as top-level keys or
15567 array elements?
15568 </para>
15569 <para>
15570 <literal>'["a", "b", "c"]'::jsonb ?&amp; array['a', 'b']</literal>
15571 <returnvalue>t</returnvalue>
15572 </para></entry>
15573 </row>
15575 <row>
15576 <entry role="func_table_entry"><para role="func_signature">
15577 <type>jsonb</type> <literal>||</literal> <type>jsonb</type>
15578 <returnvalue>jsonb</returnvalue>
15579 </para>
15580 <para>
15581 Concatenates two <type>jsonb</type> values.
15582 Concatenating two arrays generates an array containing all the
15583 elements of each input. Concatenating two objects generates an
15584 object containing the union of their
15585 keys, taking the second object's value when there are duplicate keys.
15586 All other cases are treated by converting a non-array input into a
15587 single-element array, and then proceeding as for two arrays.
15588 Does not operate recursively: only the top-level array or object
15589 structure is merged.
15590 </para>
15591 <para>
15592 <literal>'["a", "b"]'::jsonb || '["a", "d"]'::jsonb</literal>
15593 <returnvalue>["a", "b", "a", "d"]</returnvalue>
15594 </para>
15595 <para>
15596 <literal>'{"a": "b"}'::jsonb || '{"c": "d"}'::jsonb</literal>
15597 <returnvalue>{"a": "b", "c": "d"}</returnvalue>
15598 </para>
15599 <para>
15600 <literal>'[1, 2]'::jsonb || '3'::jsonb</literal>
15601 <returnvalue>[1, 2, 3]</returnvalue>
15602 </para>
15603 <para>
15604 <literal>'{"a": "b"}'::jsonb || '42'::jsonb</literal>
15605 <returnvalue>[{"a": "b"}, 42]</returnvalue>
15606 </para>
15607 <para>
15608 To append an array to another array as a single entry, wrap it
15609 in an additional layer of array, for example:
15610 </para>
15611 <para>
15612 <literal>'[1, 2]'::jsonb || jsonb_build_array('[3, 4]'::jsonb)</literal>
15613 <returnvalue>[1, 2, [3, 4]]</returnvalue>
15614 </para></entry>
15615 </row>
15617 <row>
15618 <entry role="func_table_entry"><para role="func_signature">
15619 <type>jsonb</type> <literal>-</literal> <type>text</type>
15620 <returnvalue>jsonb</returnvalue>
15621 </para>
15622 <para>
15623 Deletes a key (and its value) from a JSON object, or matching string
15624 value(s) from a JSON array.
15625 </para>
15626 <para>
15627 <literal>'{"a": "b", "c": "d"}'::jsonb - 'a'</literal>
15628 <returnvalue>{"c": "d"}</returnvalue>
15629 </para>
15630 <para>
15631 <literal>'["a", "b", "c", "b"]'::jsonb - 'b'</literal>
15632 <returnvalue>["a", "c"]</returnvalue>
15633 </para></entry>
15634 </row>
15636 <row>
15637 <entry role="func_table_entry"><para role="func_signature">
15638 <type>jsonb</type> <literal>-</literal> <type>text[]</type>
15639 <returnvalue>jsonb</returnvalue>
15640 </para>
15641 <para>
15642 Deletes all matching keys or array elements from the left operand.
15643 </para>
15644 <para>
15645 <literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[]</literal>
15646 <returnvalue>{}</returnvalue>
15647 </para></entry>
15648 </row>
15650 <row>
15651 <entry role="func_table_entry"><para role="func_signature">
15652 <type>jsonb</type> <literal>-</literal> <type>integer</type>
15653 <returnvalue>jsonb</returnvalue>
15654 </para>
15655 <para>
15656 Deletes the array element with specified index (negative
15657 integers count from the end). Throws an error if JSON value
15658 is not an array.
15659 </para>
15660 <para>
15661 <literal>'["a", "b"]'::jsonb - 1 </literal>
15662 <returnvalue>["a"]</returnvalue>
15663 </para></entry>
15664 </row>
15666 <row>
15667 <entry role="func_table_entry"><para role="func_signature">
15668 <type>jsonb</type> <literal>#-</literal> <type>text[]</type>
15669 <returnvalue>jsonb</returnvalue>
15670 </para>
15671 <para>
15672 Deletes the field or array element at the specified path, where path
15673 elements can be either field keys or array indexes.
15674 </para>
15675 <para>
15676 <literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal>
15677 <returnvalue>["a", {}]</returnvalue>
15678 </para></entry>
15679 </row>
15681 <row>
15682 <entry role="func_table_entry"><para role="func_signature">
15683 <type>jsonb</type> <literal>@?</literal> <type>jsonpath</type>
15684 <returnvalue>boolean</returnvalue>
15685 </para>
15686 <para>
15687 Does JSON path return any item for the specified JSON value?
15688 </para>
15689 <para>
15690 <literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal>
15691 <returnvalue>t</returnvalue>
15692 </para></entry>
15693 </row>
15695 <row>
15696 <entry role="func_table_entry"><para role="func_signature">
15697 <type>jsonb</type> <literal>@@</literal> <type>jsonpath</type>
15698 <returnvalue>boolean</returnvalue>
15699 </para>
15700 <para>
15701 Returns the result of a JSON path predicate check for the
15702 specified JSON value. Only the first item of the result is taken into
15703 account. If the result is not Boolean, then <literal>NULL</literal>
15704 is returned.
15705 </para>
15706 <para>
15707 <literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal>
15708 <returnvalue>t</returnvalue>
15709 </para></entry>
15710 </row>
15711 </tbody>
15712 </tgroup>
15713 </table>
15715 <note>
15716 <para>
15717 The <type>jsonpath</type> operators <literal>@?</literal>
15718 and <literal>@@</literal> suppress the following errors: missing object
15719 field or array element, unexpected JSON item type, datetime and numeric
15720 errors. The <type>jsonpath</type>-related functions described below can
15721 also be told to suppress these types of errors. This behavior might be
15722 helpful when searching JSON document collections of varying structure.
15723 </para>
15724 </note>
15726 <para>
15727 <xref linkend="functions-json-creation-table"/> shows the functions that are
15728 available for constructing <type>json</type> and <type>jsonb</type> values.
15729 Some functions in this table have a <literal>RETURNING</literal> clause,
15730 which specifies the data type returned. It must be one of <type>json</type>,
15731 <type>jsonb</type>, <type>bytea</type>, a character string type (<type>text</type>,
15732 <type>char</type>, <type>varchar</type>, or <type>nchar</type>), or a type
15733 for which there is a cast from <type>json</type> to that type.
15734 By default, the <type>json</type> type is returned.
15735 </para>
15737 <table id="functions-json-creation-table">
15738 <title>JSON Creation Functions</title>
15739 <tgroup cols="1">
15740 <thead>
15741 <row>
15742 <entry role="func_table_entry"><para role="func_signature">
15743 Function
15744 </para>
15745 <para>
15746 Description
15747 </para>
15748 <para>
15749 Example(s)
15750 </para></entry>
15751 </row>
15752 </thead>
15754 <tbody>
15755 <row>
15756 <entry role="func_table_entry"><para role="func_signature">
15757 <indexterm>
15758 <primary>to_json</primary>
15759 </indexterm>
15760 <function>to_json</function> ( <type>anyelement</type> )
15761 <returnvalue>json</returnvalue>
15762 </para>
15763 <para role="func_signature">
15764 <indexterm>
15765 <primary>to_jsonb</primary>
15766 </indexterm>
15767 <function>to_jsonb</function> ( <type>anyelement</type> )
15768 <returnvalue>jsonb</returnvalue>
15769 </para>
15770 <para>
15771 Converts any SQL value to <type>json</type> or <type>jsonb</type>.
15772 Arrays and composites are converted recursively to arrays and
15773 objects (multidimensional arrays become arrays of arrays in JSON).
15774 Otherwise, if there is a cast from the SQL data type
15775 to <type>json</type>, the cast function will be used to perform the
15776 conversion;<footnote>
15777 <para>
15778 For example, the <xref linkend="hstore"/> extension has a cast
15779 from <type>hstore</type> to <type>json</type>, so that
15780 <type>hstore</type> values converted via the JSON creation functions
15781 will be represented as JSON objects, not as primitive string values.
15782 </para>
15783 </footnote>
15784 otherwise, a scalar JSON value is produced. For any scalar other than
15785 a number, a Boolean, or a null value, the text representation will be
15786 used, with escaping as necessary to make it a valid JSON string value.
15787 </para>
15788 <para>
15789 <literal>to_json('Fred said "Hi."'::text)</literal>
15790 <returnvalue>"Fred said \"Hi.\""</returnvalue>
15791 </para>
15792 <para>
15793 <literal>to_jsonb(row(42, 'Fred said "Hi."'::text))</literal>
15794 <returnvalue>{"f1": 42, "f2": "Fred said \"Hi.\""}</returnvalue>
15795 </para></entry>
15796 </row>
15798 <row>
15799 <entry role="func_table_entry"><para role="func_signature">
15800 <indexterm>
15801 <primary>array_to_json</primary>
15802 </indexterm>
15803 <function>array_to_json</function> ( <type>anyarray</type> <optional>, <type>boolean</type> </optional> )
15804 <returnvalue>json</returnvalue>
15805 </para>
15806 <para>
15807 Converts an SQL array to a JSON array. The behavior is the same
15808 as <function>to_json</function> except that line feeds will be added
15809 between top-level array elements if the optional boolean parameter is
15810 true.
15811 </para>
15812 <para>
15813 <literal>array_to_json('{{1,5},{99,100}}'::int[])</literal>
15814 <returnvalue>[[1,5],[99,100]]</returnvalue>
15815 </para></entry>
15816 </row>
15818 <row>
15819 <!--
15820 Note that this is barely legible in the output; it looks like a
15821 salad of braces and brackets. It would be better to split it out
15822 in multiple lines, but that's surprisingly hard to do in a way that
15823 matches in HTML and PDF output. Other standard SQL/JSON functions
15824 have the same problem.
15826 <entry role="func_table_entry"><para role="func_signature">
15827 <indexterm><primary>json_array</primary></indexterm>
15828 <function>json_array</function> (
15829 <optional> { <replaceable>value_expression</replaceable> <optional> <literal>FORMAT JSON</literal> </optional> } <optional>, ...</optional> </optional>
15830 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
15831 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
15832 </para>
15833 <para role="func_signature">
15834 <function>json_array</function> (
15835 <optional> <replaceable>query_expression</replaceable> </optional>
15836 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
15837 </para>
15838 <para>
15839 Constructs a JSON array from either a series of
15840 <replaceable>value_expression</replaceable> parameters or from the results
15841 of <replaceable>query_expression</replaceable>,
15842 which must be a SELECT query returning a single column. If
15843 <literal>ABSENT ON NULL</literal> is specified, NULL values are ignored.
15844 This is always the case if a
15845 <replaceable>query_expression</replaceable> is used.
15846 </para>
15847 <para>
15848 <literal>json_array(1,true,json '{"a":null}')</literal>
15849 <returnvalue>[1, true, {"a":null}]</returnvalue>
15850 </para>
15851 <para>
15852 <literal>json_array(SELECT * FROM (VALUES(1),(2)) t)</literal>
15853 <returnvalue>[1, 2]</returnvalue>
15854 </para></entry>
15855 </row>
15857 <row>
15858 <entry role="func_table_entry"><para role="func_signature">
15859 <indexterm>
15860 <primary>row_to_json</primary>
15861 </indexterm>
15862 <function>row_to_json</function> ( <type>record</type> <optional>, <type>boolean</type> </optional> )
15863 <returnvalue>json</returnvalue>
15864 </para>
15865 <para>
15866 Converts an SQL composite value to a JSON object. The behavior is the
15867 same as <function>to_json</function> except that line feeds will be
15868 added between top-level elements if the optional boolean parameter is
15869 true.
15870 </para>
15871 <para>
15872 <literal>row_to_json(row(1,'foo'))</literal>
15873 <returnvalue>{"f1":1,"f2":"foo"}</returnvalue>
15874 </para></entry>
15875 </row>
15877 <row>
15878 <entry role="func_table_entry"><para role="func_signature">
15879 <indexterm>
15880 <primary>json_build_array</primary>
15881 </indexterm>
15882 <function>json_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15883 <returnvalue>json</returnvalue>
15884 </para>
15885 <para role="func_signature">
15886 <indexterm>
15887 <primary>jsonb_build_array</primary>
15888 </indexterm>
15889 <function>jsonb_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15890 <returnvalue>jsonb</returnvalue>
15891 </para>
15892 <para>
15893 Builds a possibly-heterogeneously-typed JSON array out of a variadic
15894 argument list. Each argument is converted as
15895 per <function>to_json</function> or <function>to_jsonb</function>.
15896 </para>
15897 <para>
15898 <literal>json_build_array(1, 2, 'foo', 4, 5)</literal>
15899 <returnvalue>[1, 2, "foo", 4, 5]</returnvalue>
15900 </para></entry>
15901 </row>
15903 <row>
15904 <entry role="func_table_entry"><para role="func_signature">
15905 <indexterm>
15906 <primary>json_build_object</primary>
15907 </indexterm>
15908 <function>json_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15909 <returnvalue>json</returnvalue>
15910 </para>
15911 <para role="func_signature">
15912 <indexterm>
15913 <primary>jsonb_build_object</primary>
15914 </indexterm>
15915 <function>jsonb_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15916 <returnvalue>jsonb</returnvalue>
15917 </para>
15918 <para>
15919 Builds a JSON object out of a variadic argument list. By convention,
15920 the argument list consists of alternating keys and values. Key
15921 arguments are coerced to text; value arguments are converted as
15922 per <function>to_json</function> or <function>to_jsonb</function>.
15923 </para>
15924 <para>
15925 <literal>json_build_object('foo', 1, 2, row(3,'bar'))</literal>
15926 <returnvalue>{"foo" : 1, "2" : {"f1":3,"f2":"bar"}}</returnvalue>
15927 </para></entry>
15928 </row>
15930 <row>
15931 <entry role="func_table_entry"><para role="func_signature">
15932 <indexterm><primary>json_object</primary></indexterm>
15933 <function>json_object</function> (
15934 <optional> { <replaceable>key_expression</replaceable> { <literal>VALUE</literal> | ':' }
15935 <replaceable>value_expression</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> }<optional>, ...</optional> </optional>
15936 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
15937 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
15938 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
15939 </para>
15940 <para>
15941 Constructs a JSON object of all the key/value pairs given,
15942 or an empty object if none are given.
15943 <replaceable>key_expression</replaceable> is a scalar expression
15944 defining the <acronym>JSON</acronym> key, which is
15945 converted to the <type>text</type> type.
15946 It cannot be <literal>NULL</literal> nor can it
15947 belong to a type that has a cast to the <type>json</type> type.
15948 If <literal>WITH UNIQUE KEYS</literal> is specified, there must not
15949 be any duplicate <replaceable>key_expression</replaceable>.
15950 Any pair for which the <replaceable>value_expression</replaceable>
15951 evaluates to <literal>NULL</literal> is omitted from the output
15952 if <literal>ABSENT ON NULL</literal> is specified;
15953 if <literal>NULL ON NULL</literal> is specified or the clause
15954 omitted, the key is included with value <literal>NULL</literal>.
15955 </para>
15956 <para>
15957 <literal>json_object('code' VALUE 'P123', 'title': 'Jaws')</literal>
15958 <returnvalue>{"code" : "P123", "title" : "Jaws"}</returnvalue>
15959 </para></entry>
15960 </row>
15962 <row>
15963 <entry role="func_table_entry"><para role="func_signature">
15964 <indexterm>
15965 <primary>json_object</primary>
15966 </indexterm>
15967 <function>json_object</function> ( <type>text[]</type> )
15968 <returnvalue>json</returnvalue>
15969 </para>
15970 <para role="func_signature">
15971 <indexterm>
15972 <primary>jsonb_object</primary>
15973 </indexterm>
15974 <function>jsonb_object</function> ( <type>text[]</type> )
15975 <returnvalue>jsonb</returnvalue>
15976 </para>
15977 <para>
15978 Builds a JSON object out of a text array. The array must have either
15979 exactly one dimension with an even number of members, in which case
15980 they are taken as alternating key/value pairs, or two dimensions
15981 such that each inner array has exactly two elements, which
15982 are taken as a key/value pair. All values are converted to JSON
15983 strings.
15984 </para>
15985 <para>
15986 <literal>json_object('{a, 1, b, "def", c, 3.5}')</literal>
15987 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
15988 </para>
15989 <para><literal>json_object('{{a, 1}, {b, "def"}, {c, 3.5}}')</literal>
15990 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
15991 </para></entry>
15992 </row>
15994 <row>
15995 <entry role="func_table_entry"><para role="func_signature">
15996 <function>json_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
15997 <returnvalue>json</returnvalue>
15998 </para>
15999 <para role="func_signature">
16000 <function>jsonb_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
16001 <returnvalue>jsonb</returnvalue>
16002 </para>
16003 <para>
16004 This form of <function>json_object</function> takes keys and values
16005 pairwise from separate text arrays. Otherwise it is identical to
16006 the one-argument form.
16007 </para>
16008 <para>
16009 <literal>json_object('{a,b}', '{1,2}')</literal>
16010 <returnvalue>{"a": "1", "b": "2"}</returnvalue>
16011 </para></entry>
16012 </row>
16013 </tbody>
16014 </tgroup>
16015 </table>
16017 <para>
16018 <xref linkend="functions-sqljson-misc" /> details SQL/JSON
16019 facilities for testing JSON.
16020 </para>
16022 <table id="functions-sqljson-misc">
16023 <title>SQL/JSON Testing Functions</title>
16024 <tgroup cols="1">
16025 <thead>
16026 <row>
16027 <entry role="func_table_entry"><para role="func_signature">
16028 Function signature
16029 </para>
16030 <para>
16031 Description
16032 </para>
16033 <para>
16034 Example(s)
16035 </para></entry>
16036 </row>
16037 </thead>
16038 <tbody>
16039 <row>
16040 <entry role="func_table_entry"><para role="func_signature">
16041 <indexterm><primary>IS JSON</primary></indexterm>
16042 <replaceable>expression</replaceable> <literal>IS</literal> <optional> <literal>NOT</literal> </optional> <literal>JSON</literal>
16043 <optional> { <literal>VALUE</literal> | <literal>SCALAR</literal> | <literal>ARRAY</literal> | <literal>OBJECT</literal> } </optional>
16044 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
16045 </para>
16046 <para>
16047 This predicate tests whether <replaceable>expression</replaceable> can be
16048 parsed as JSON, possibly of a specified type.
16049 If <literal>SCALAR</literal> or <literal>ARRAY</literal> or
16050 <literal>OBJECT</literal> is specified, the
16051 test is whether or not the JSON is of that particular type. If
16052 <literal>WITH UNIQUE KEYS</literal> is specified, then any object in the
16053 <replaceable>expression</replaceable> is also tested to see if it
16054 has duplicate keys.
16055 </para>
16056 <para>
16057 <programlisting>
16058 SELECT js,
16059 js IS JSON "json?",
16060 js IS JSON SCALAR "scalar?",
16061 js IS JSON OBJECT "object?",
16062 js IS JSON ARRAY "array?"
16063 FROM (VALUES
16064 ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'),('abc')) foo(js);
16065 js | json? | scalar? | object? | array?
16066 ------------+-------+---------+---------+--------
16067 123 | t | t | f | f
16068 "abc" | t | t | f | f
16069 {"a": "b"} | t | f | t | f
16070 [1,2] | t | f | f | t
16071 abc | f | f | f | f
16072 </programlisting>
16073 </para>
16074 <para>
16075 <programlisting>
16076 SELECT js,
16077 js IS JSON OBJECT "object?",
16078 js IS JSON ARRAY "array?",
16079 js IS JSON ARRAY WITH UNIQUE KEYS "array w. UK?",
16080 js IS JSON ARRAY WITHOUT UNIQUE KEYS "array w/o UK?"
16081 FROM (VALUES ('[{"a":"1"},
16082 {"b":"2","b":"3"}]')) foo(js);
16083 -[ RECORD 1 ]-+--------------------
16084 js | [{"a":"1"}, +
16085 | {"b":"2","b":"3"}]
16086 object? | f
16087 array? | t
16088 array w. UK? | f
16089 array w/o UK? | t
16090 </programlisting>
16091 </para></entry>
16092 </row>
16093 </tbody>
16094 </tgroup>
16095 </table>
16097 <para>
16098 <xref linkend="functions-json-processing-table"/> shows the functions that
16099 are available for processing <type>json</type> and <type>jsonb</type> values.
16100 </para>
16102 <table id="functions-json-processing-table">
16103 <title>JSON Processing Functions</title>
16104 <tgroup cols="1">
16105 <thead>
16106 <row>
16107 <entry role="func_table_entry"><para role="func_signature">
16108 Function
16109 </para>
16110 <para>
16111 Description
16112 </para>
16113 <para>
16114 Example(s)
16115 </para></entry>
16116 </row>
16117 </thead>
16119 <tbody>
16120 <row>
16121 <entry role="func_table_entry"><para role="func_signature">
16122 <indexterm>
16123 <primary>json_array_elements</primary>
16124 </indexterm>
16125 <function>json_array_elements</function> ( <type>json</type> )
16126 <returnvalue>setof json</returnvalue>
16127 </para>
16128 <para role="func_signature">
16129 <indexterm>
16130 <primary>jsonb_array_elements</primary>
16131 </indexterm>
16132 <function>jsonb_array_elements</function> ( <type>jsonb</type> )
16133 <returnvalue>setof jsonb</returnvalue>
16134 </para>
16135 <para>
16136 Expands the top-level JSON array into a set of JSON values.
16137 </para>
16138 <para>
16139 <literal>select * from json_array_elements('[1,true, [2,false]]')</literal>
16140 <returnvalue></returnvalue>
16141 <programlisting>
16142 value
16143 -----------
16145 true
16146 [2,false]
16147 </programlisting>
16148 </para></entry>
16149 </row>
16151 <row>
16152 <entry role="func_table_entry"><para role="func_signature">
16153 <indexterm>
16154 <primary>json_array_elements_text</primary>
16155 </indexterm>
16156 <function>json_array_elements_text</function> ( <type>json</type> )
16157 <returnvalue>setof text</returnvalue>
16158 </para>
16159 <para role="func_signature">
16160 <indexterm>
16161 <primary>jsonb_array_elements_text</primary>
16162 </indexterm>
16163 <function>jsonb_array_elements_text</function> ( <type>jsonb</type> )
16164 <returnvalue>setof text</returnvalue>
16165 </para>
16166 <para>
16167 Expands the top-level JSON array into a set of <type>text</type> values.
16168 </para>
16169 <para>
16170 <literal>select * from json_array_elements_text('["foo", "bar"]')</literal>
16171 <returnvalue></returnvalue>
16172 <programlisting>
16173 value
16174 -----------
16177 </programlisting>
16178 </para></entry>
16179 </row>
16181 <row>
16182 <entry role="func_table_entry"><para role="func_signature">
16183 <indexterm>
16184 <primary>json_array_length</primary>
16185 </indexterm>
16186 <function>json_array_length</function> ( <type>json</type> )
16187 <returnvalue>integer</returnvalue>
16188 </para>
16189 <para role="func_signature">
16190 <indexterm>
16191 <primary>jsonb_array_length</primary>
16192 </indexterm>
16193 <function>jsonb_array_length</function> ( <type>jsonb</type> )
16194 <returnvalue>integer</returnvalue>
16195 </para>
16196 <para>
16197 Returns the number of elements in the top-level JSON array.
16198 </para>
16199 <para>
16200 <literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal>
16201 <returnvalue>5</returnvalue>
16202 </para>
16203 <para>
16204 <literal>jsonb_array_length('[]')</literal>
16205 <returnvalue>0</returnvalue>
16206 </para></entry>
16207 </row>
16209 <row>
16210 <entry role="func_table_entry"><para role="func_signature">
16211 <indexterm>
16212 <primary>json_each</primary>
16213 </indexterm>
16214 <function>json_each</function> ( <type>json</type> )
16215 <returnvalue>setof record</returnvalue>
16216 ( <parameter>key</parameter> <type>text</type>,
16217 <parameter>value</parameter> <type>json</type> )
16218 </para>
16219 <para role="func_signature">
16220 <indexterm>
16221 <primary>jsonb_each</primary>
16222 </indexterm>
16223 <function>jsonb_each</function> ( <type>jsonb</type> )
16224 <returnvalue>setof record</returnvalue>
16225 ( <parameter>key</parameter> <type>text</type>,
16226 <parameter>value</parameter> <type>jsonb</type> )
16227 </para>
16228 <para>
16229 Expands the top-level JSON object into a set of key/value pairs.
16230 </para>
16231 <para>
16232 <literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal>
16233 <returnvalue></returnvalue>
16234 <programlisting>
16235 key | value
16236 -----+-------
16237 a | "foo"
16238 b | "bar"
16239 </programlisting>
16240 </para></entry>
16241 </row>
16243 <row>
16244 <entry role="func_table_entry"><para role="func_signature">
16245 <indexterm>
16246 <primary>json_each_text</primary>
16247 </indexterm>
16248 <function>json_each_text</function> ( <type>json</type> )
16249 <returnvalue>setof record</returnvalue>
16250 ( <parameter>key</parameter> <type>text</type>,
16251 <parameter>value</parameter> <type>text</type> )
16252 </para>
16253 <para role="func_signature">
16254 <indexterm>
16255 <primary>jsonb_each_text</primary>
16256 </indexterm>
16257 <function>jsonb_each_text</function> ( <type>jsonb</type> )
16258 <returnvalue>setof record</returnvalue>
16259 ( <parameter>key</parameter> <type>text</type>,
16260 <parameter>value</parameter> <type>text</type> )
16261 </para>
16262 <para>
16263 Expands the top-level JSON object into a set of key/value pairs.
16264 The returned <parameter>value</parameter>s will be of
16265 type <type>text</type>.
16266 </para>
16267 <para>
16268 <literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal>
16269 <returnvalue></returnvalue>
16270 <programlisting>
16271 key | value
16272 -----+-------
16273 a | foo
16274 b | bar
16275 </programlisting>
16276 </para></entry>
16277 </row>
16279 <row>
16280 <entry role="func_table_entry"><para role="func_signature">
16281 <indexterm>
16282 <primary>json_extract_path</primary>
16283 </indexterm>
16284 <function>json_extract_path</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16285 <returnvalue>json</returnvalue>
16286 </para>
16287 <para role="func_signature">
16288 <indexterm>
16289 <primary>jsonb_extract_path</primary>
16290 </indexterm>
16291 <function>jsonb_extract_path</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16292 <returnvalue>jsonb</returnvalue>
16293 </para>
16294 <para>
16295 Extracts JSON sub-object at the specified path.
16296 (This is functionally equivalent to the <literal>#&gt;</literal>
16297 operator, but writing the path out as a variadic list can be more
16298 convenient in some cases.)
16299 </para>
16300 <para>
16301 <literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
16302 <returnvalue>"foo"</returnvalue>
16303 </para></entry>
16304 </row>
16306 <row>
16307 <entry role="func_table_entry"><para role="func_signature">
16308 <indexterm>
16309 <primary>json_extract_path_text</primary>
16310 </indexterm>
16311 <function>json_extract_path_text</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16312 <returnvalue>text</returnvalue>
16313 </para>
16314 <para role="func_signature">
16315 <indexterm>
16316 <primary>jsonb_extract_path_text</primary>
16317 </indexterm>
16318 <function>jsonb_extract_path_text</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16319 <returnvalue>text</returnvalue>
16320 </para>
16321 <para>
16322 Extracts JSON sub-object at the specified path as <type>text</type>.
16323 (This is functionally equivalent to the <literal>#&gt;&gt;</literal>
16324 operator.)
16325 </para>
16326 <para>
16327 <literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
16328 <returnvalue>foo</returnvalue>
16329 </para></entry>
16330 </row>
16332 <row>
16333 <entry role="func_table_entry"><para role="func_signature">
16334 <indexterm>
16335 <primary>json_object_keys</primary>
16336 </indexterm>
16337 <function>json_object_keys</function> ( <type>json</type> )
16338 <returnvalue>setof text</returnvalue>
16339 </para>
16340 <para role="func_signature">
16341 <indexterm>
16342 <primary>jsonb_object_keys</primary>
16343 </indexterm>
16344 <function>jsonb_object_keys</function> ( <type>jsonb</type> )
16345 <returnvalue>setof text</returnvalue>
16346 </para>
16347 <para>
16348 Returns the set of keys in the top-level JSON object.
16349 </para>
16350 <para>
16351 <literal>select * from json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal>
16352 <returnvalue></returnvalue>
16353 <programlisting>
16354 json_object_keys
16355 ------------------
16358 </programlisting>
16359 </para></entry>
16360 </row>
16362 <row>
16363 <entry role="func_table_entry"><para role="func_signature">
16364 <indexterm>
16365 <primary>json_populate_record</primary>
16366 </indexterm>
16367 <function>json_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16368 <returnvalue>anyelement</returnvalue>
16369 </para>
16370 <para role="func_signature">
16371 <indexterm>
16372 <primary>jsonb_populate_record</primary>
16373 </indexterm>
16374 <function>jsonb_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16375 <returnvalue>anyelement</returnvalue>
16376 </para>
16377 <para>
16378 Expands the top-level JSON object to a row having the composite type
16379 of the <parameter>base</parameter> argument. The JSON object
16380 is scanned for fields whose names match column names of the output row
16381 type, and their values are inserted into those columns of the output.
16382 (Fields that do not correspond to any output column name are ignored.)
16383 In typical use, the value of <parameter>base</parameter> is just
16384 <literal>NULL</literal>, which means that any output columns that do
16385 not match any object field will be filled with nulls. However,
16386 if <parameter>base</parameter> isn't <literal>NULL</literal> then
16387 the values it contains will be used for unmatched columns.
16388 </para>
16389 <para>
16390 To convert a JSON value to the SQL type of an output column, the
16391 following rules are applied in sequence:
16392 <itemizedlist spacing="compact">
16393 <listitem>
16394 <para>
16395 A JSON null value is converted to an SQL null in all cases.
16396 </para>
16397 </listitem>
16398 <listitem>
16399 <para>
16400 If the output column is of type <type>json</type>
16401 or <type>jsonb</type>, the JSON value is just reproduced exactly.
16402 </para>
16403 </listitem>
16404 <listitem>
16405 <para>
16406 If the output column is a composite (row) type, and the JSON value
16407 is a JSON object, the fields of the object are converted to columns
16408 of the output row type by recursive application of these rules.
16409 </para>
16410 </listitem>
16411 <listitem>
16412 <para>
16413 Likewise, if the output column is an array type and the JSON value
16414 is a JSON array, the elements of the JSON array are converted to
16415 elements of the output array by recursive application of these
16416 rules.
16417 </para>
16418 </listitem>
16419 <listitem>
16420 <para>
16421 Otherwise, if the JSON value is a string, the contents of the
16422 string are fed to the input conversion function for the column's
16423 data type.
16424 </para>
16425 </listitem>
16426 <listitem>
16427 <para>
16428 Otherwise, the ordinary text representation of the JSON value is
16429 fed to the input conversion function for the column's data type.
16430 </para>
16431 </listitem>
16432 </itemizedlist>
16433 </para>
16434 <para>
16435 While the example below uses a constant JSON value, typical use would
16436 be to reference a <type>json</type> or <type>jsonb</type> column
16437 laterally from another table in the query's <literal>FROM</literal>
16438 clause. Writing <function>json_populate_record</function> in
16439 the <literal>FROM</literal> clause is good practice, since all of the
16440 extracted columns are available for use without duplicate function
16441 calls.
16442 </para>
16443 <para>
16444 <literal>create type subrowtype as (d int, e text);</literal>
16445 <literal>create type myrowtype as (a int, b text[], c subrowtype);</literal>
16446 </para>
16447 <para>
16448 <literal>select * from json_populate_record(null::myrowtype,
16449 '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}, "x": "foo"}')</literal>
16450 <returnvalue></returnvalue>
16451 <programlisting>
16452 a | b | c
16453 ---+-----------+-------------
16454 1 | {2,"a b"} | (4,"a b c")
16455 </programlisting>
16456 </para></entry>
16457 </row>
16459 <row>
16460 <entry role="func_table_entry"><para role="func_signature">
16461 <indexterm>
16462 <primary>json_populate_recordset</primary>
16463 </indexterm>
16464 <function>json_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16465 <returnvalue>setof anyelement</returnvalue>
16466 </para>
16467 <para role="func_signature">
16468 <indexterm>
16469 <primary>jsonb_populate_recordset</primary>
16470 </indexterm>
16471 <function>jsonb_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16472 <returnvalue>setof anyelement</returnvalue>
16473 </para>
16474 <para>
16475 Expands the top-level JSON array of objects to a set of rows having
16476 the composite type of the <parameter>base</parameter> argument.
16477 Each element of the JSON array is processed as described above
16478 for <function>json[b]_populate_record</function>.
16479 </para>
16480 <para>
16481 <literal>create type twoints as (a int, b int);</literal>
16482 </para>
16483 <para>
16484 <literal>select * from json_populate_recordset(null::twoints, '[{"a":1,"b":2}, {"a":3,"b":4}]')</literal>
16485 <returnvalue></returnvalue>
16486 <programlisting>
16487 a | b
16488 ---+---
16489 1 | 2
16490 3 | 4
16491 </programlisting>
16492 </para></entry>
16493 </row>
16495 <row>
16496 <entry role="func_table_entry"><para role="func_signature">
16497 <indexterm>
16498 <primary>json_to_record</primary>
16499 </indexterm>
16500 <function>json_to_record</function> ( <type>json</type> )
16501 <returnvalue>record</returnvalue>
16502 </para>
16503 <para role="func_signature">
16504 <indexterm>
16505 <primary>jsonb_to_record</primary>
16506 </indexterm>
16507 <function>jsonb_to_record</function> ( <type>jsonb</type> )
16508 <returnvalue>record</returnvalue>
16509 </para>
16510 <para>
16511 Expands the top-level JSON object to a row having the composite type
16512 defined by an <literal>AS</literal> clause. (As with all functions
16513 returning <type>record</type>, the calling query must explicitly
16514 define the structure of the record with an <literal>AS</literal>
16515 clause.) The output record is filled from fields of the JSON object,
16516 in the same way as described above
16517 for <function>json[b]_populate_record</function>. Since there is no
16518 input record value, unmatched columns are always filled with nulls.
16519 </para>
16520 <para>
16521 <literal>create type myrowtype as (a int, b text);</literal>
16522 </para>
16523 <para>
16524 <literal>select * from json_to_record('{"a":1,"b":[1,2,3],"c":[1,2,3],"e":"bar","r": {"a": 123, "b": "a b c"}}') as x(a int, b text, c int[], d text, r myrowtype)</literal>
16525 <returnvalue></returnvalue>
16526 <programlisting>
16527 a | b | c | d | r
16528 ---+---------+---------+---+---------------
16529 1 | [1,2,3] | {1,2,3} | | (123,"a b c")
16530 </programlisting>
16531 </para></entry>
16532 </row>
16534 <row>
16535 <entry role="func_table_entry"><para role="func_signature">
16536 <indexterm>
16537 <primary>json_to_recordset</primary>
16538 </indexterm>
16539 <function>json_to_recordset</function> ( <type>json</type> )
16540 <returnvalue>setof record</returnvalue>
16541 </para>
16542 <para role="func_signature">
16543 <indexterm>
16544 <primary>jsonb_to_recordset</primary>
16545 </indexterm>
16546 <function>jsonb_to_recordset</function> ( <type>jsonb</type> )
16547 <returnvalue>setof record</returnvalue>
16548 </para>
16549 <para>
16550 Expands the top-level JSON array of objects to a set of rows having
16551 the composite type defined by an <literal>AS</literal> clause. (As
16552 with all functions returning <type>record</type>, the calling query
16553 must explicitly define the structure of the record with
16554 an <literal>AS</literal> clause.) Each element of the JSON array is
16555 processed as described above
16556 for <function>json[b]_populate_record</function>.
16557 </para>
16558 <para>
16559 <literal>select * from json_to_recordset('[{"a":1,"b":"foo"}, {"a":"2","c":"bar"}]') as x(a int, b text)</literal>
16560 <returnvalue></returnvalue>
16561 <programlisting>
16562 a | b
16563 ---+-----
16564 1 | foo
16566 </programlisting>
16567 </para></entry>
16568 </row>
16570 <row>
16571 <entry role="func_table_entry"><para role="func_signature">
16572 <indexterm>
16573 <primary>jsonb_set</primary>
16574 </indexterm>
16575 <function>jsonb_set</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>text[]</type>, <parameter>new_value</parameter> <type>jsonb</type> <optional>, <parameter>create_if_missing</parameter> <type>boolean</type> </optional> )
16576 <returnvalue>jsonb</returnvalue>
16577 </para>
16578 <para>
16579 Returns <parameter>target</parameter>
16580 with the item designated by <parameter>path</parameter>
16581 replaced by <parameter>new_value</parameter>, or with
16582 <parameter>new_value</parameter> added if
16583 <parameter>create_if_missing</parameter> is true (which is the
16584 default) and the item designated by <parameter>path</parameter>
16585 does not exist.
16586 All earlier steps in the path must exist, or
16587 the <parameter>target</parameter> is returned unchanged.
16588 As with the path oriented operators, negative integers that
16589 appear in the <parameter>path</parameter> count from the end
16590 of JSON arrays.
16591 If the last path step is an array index that is out of range,
16592 and <parameter>create_if_missing</parameter> is true, the new
16593 value is added at the beginning of the array if the index is negative,
16594 or at the end of the array if it is positive.
16595 </para>
16596 <para>
16597 <literal>jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', '[2,3,4]', false)</literal>
16598 <returnvalue>[{"f1": [2, 3, 4], "f2": null}, 2, null, 3]</returnvalue>
16599 </para>
16600 <para>
16601 <literal>jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}', '[2,3,4]')</literal>
16602 <returnvalue>[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</returnvalue>
16603 </para></entry>
16604 </row>
16606 <row>
16607 <entry role="func_table_entry"><para role="func_signature">
16608 <indexterm>
16609 <primary>jsonb_set_lax</primary>
16610 </indexterm>
16611 <function>jsonb_set_lax</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>text[]</type>, <parameter>new_value</parameter> <type>jsonb</type> <optional>, <parameter>create_if_missing</parameter> <type>boolean</type> <optional>, <parameter>null_value_treatment</parameter> <type>text</type> </optional></optional> )
16612 <returnvalue>jsonb</returnvalue>
16613 </para>
16614 <para>
16615 If <parameter>new_value</parameter> is not <literal>NULL</literal>,
16616 behaves identically to <literal>jsonb_set</literal>. Otherwise behaves
16617 according to the value
16618 of <parameter>null_value_treatment</parameter> which must be one
16619 of <literal>'raise_exception'</literal>,
16620 <literal>'use_json_null'</literal>, <literal>'delete_key'</literal>, or
16621 <literal>'return_target'</literal>. The default is
16622 <literal>'use_json_null'</literal>.
16623 </para>
16624 <para>
16625 <literal>jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null)</literal>
16626 <returnvalue>[{"f1": null, "f2": null}, 2, null, 3]</returnvalue>
16627 </para>
16628 <para>
16629 <literal>jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true, 'return_target')</literal>
16630 <returnvalue>[{"f1": 99, "f2": null}, 2]</returnvalue>
16631 </para></entry>
16632 </row>
16634 <row>
16635 <entry role="func_table_entry"><para role="func_signature">
16636 <indexterm>
16637 <primary>jsonb_insert</primary>
16638 </indexterm>
16639 <function>jsonb_insert</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>text[]</type>, <parameter>new_value</parameter> <type>jsonb</type> <optional>, <parameter>insert_after</parameter> <type>boolean</type> </optional> )
16640 <returnvalue>jsonb</returnvalue>
16641 </para>
16642 <para>
16643 Returns <parameter>target</parameter>
16644 with <parameter>new_value</parameter> inserted. If the item
16645 designated by the <parameter>path</parameter> is an array
16646 element, <parameter>new_value</parameter> will be inserted before
16647 that item if <parameter>insert_after</parameter> is false (which
16648 is the default), or after it
16649 if <parameter>insert_after</parameter> is true. If the item
16650 designated by the <parameter>path</parameter> is an object
16651 field, <parameter>new_value</parameter> will be inserted only if
16652 the object does not already contain that key.
16653 All earlier steps in the path must exist, or
16654 the <parameter>target</parameter> is returned unchanged.
16655 As with the path oriented operators, negative integers that
16656 appear in the <parameter>path</parameter> count from the end
16657 of JSON arrays.
16658 If the last path step is an array index that is out of range, the new
16659 value is added at the beginning of the array if the index is negative,
16660 or at the end of the array if it is positive.
16661 </para>
16662 <para>
16663 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')</literal>
16664 <returnvalue>{"a": [0, "new_value", 1, 2]}</returnvalue>
16665 </para>
16666 <para>
16667 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)</literal>
16668 <returnvalue>{"a": [0, 1, "new_value", 2]}</returnvalue>
16669 </para></entry>
16670 </row>
16672 <row>
16673 <entry role="func_table_entry"><para role="func_signature">
16674 <indexterm>
16675 <primary>json_strip_nulls</primary>
16676 </indexterm>
16677 <function>json_strip_nulls</function> ( <type>json</type> )
16678 <returnvalue>json</returnvalue>
16679 </para>
16680 <para role="func_signature">
16681 <indexterm>
16682 <primary>jsonb_strip_nulls</primary>
16683 </indexterm>
16684 <function>jsonb_strip_nulls</function> ( <type>jsonb</type> )
16685 <returnvalue>jsonb</returnvalue>
16686 </para>
16687 <para>
16688 Deletes all object fields that have null values from the given JSON
16689 value, recursively. Null values that are not object fields are
16690 untouched.
16691 </para>
16692 <para>
16693 <literal>json_strip_nulls('[{"f1":1, "f2":null}, 2, null, 3]')</literal>
16694 <returnvalue>[{"f1":1},2,null,3]</returnvalue>
16695 </para></entry>
16696 </row>
16698 <row>
16699 <entry role="func_table_entry"><para role="func_signature">
16700 <indexterm>
16701 <primary>jsonb_path_exists</primary>
16702 </indexterm>
16703 <function>jsonb_path_exists</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16704 <returnvalue>boolean</returnvalue>
16705 </para>
16706 <para>
16707 Checks whether the JSON path returns any item for the specified JSON
16708 value.
16709 If the <parameter>vars</parameter> argument is specified, it must
16710 be a JSON object, and its fields provide named values to be
16711 substituted into the <type>jsonpath</type> expression.
16712 If the <parameter>silent</parameter> argument is specified and
16713 is <literal>true</literal>, the function suppresses the same errors
16714 as the <literal>@?</literal> and <literal>@@</literal> operators do.
16715 </para>
16716 <para>
16717 <literal>jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16718 <returnvalue>t</returnvalue>
16719 </para></entry>
16720 </row>
16722 <row>
16723 <entry role="func_table_entry"><para role="func_signature">
16724 <indexterm>
16725 <primary>jsonb_path_match</primary>
16726 </indexterm>
16727 <function>jsonb_path_match</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16728 <returnvalue>boolean</returnvalue>
16729 </para>
16730 <para>
16731 Returns the result of a JSON path predicate check for the specified
16732 JSON value. Only the first item of the result is taken into account.
16733 If the result is not Boolean, then <literal>NULL</literal> is returned.
16734 The optional <parameter>vars</parameter>
16735 and <parameter>silent</parameter> arguments act the same as
16736 for <function>jsonb_path_exists</function>.
16737 </para>
16738 <para>
16739 <literal>jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max))', '{"min":2, "max":4}')</literal>
16740 <returnvalue>t</returnvalue>
16741 </para></entry>
16742 </row>
16744 <row>
16745 <entry role="func_table_entry"><para role="func_signature">
16746 <indexterm>
16747 <primary>jsonb_path_query</primary>
16748 </indexterm>
16749 <function>jsonb_path_query</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16750 <returnvalue>setof jsonb</returnvalue>
16751 </para>
16752 <para>
16753 Returns all JSON items returned by the JSON path for the specified
16754 JSON value.
16755 The optional <parameter>vars</parameter>
16756 and <parameter>silent</parameter> arguments act the same as
16757 for <function>jsonb_path_exists</function>.
16758 </para>
16759 <para>
16760 <literal>select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16761 <returnvalue></returnvalue>
16762 <programlisting>
16763 jsonb_path_query
16764 ------------------
16768 </programlisting>
16769 </para></entry>
16770 </row>
16772 <row>
16773 <entry role="func_table_entry"><para role="func_signature">
16774 <indexterm>
16775 <primary>jsonb_path_query_array</primary>
16776 </indexterm>
16777 <function>jsonb_path_query_array</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16778 <returnvalue>jsonb</returnvalue>
16779 </para>
16780 <para>
16781 Returns all JSON items returned by the JSON path for the specified
16782 JSON value, as a JSON array.
16783 The optional <parameter>vars</parameter>
16784 and <parameter>silent</parameter> arguments act the same as
16785 for <function>jsonb_path_exists</function>.
16786 </para>
16787 <para>
16788 <literal>jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16789 <returnvalue>[2, 3, 4]</returnvalue>
16790 </para></entry>
16791 </row>
16793 <row>
16794 <entry role="func_table_entry"><para role="func_signature">
16795 <indexterm>
16796 <primary>jsonb_path_query_first</primary>
16797 </indexterm>
16798 <function>jsonb_path_query_first</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16799 <returnvalue>jsonb</returnvalue>
16800 </para>
16801 <para>
16802 Returns the first JSON item returned by the JSON path for the
16803 specified JSON value. Returns <literal>NULL</literal> if there are no
16804 results.
16805 The optional <parameter>vars</parameter>
16806 and <parameter>silent</parameter> arguments act the same as
16807 for <function>jsonb_path_exists</function>.
16808 </para>
16809 <para>
16810 <literal>jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16811 <returnvalue>2</returnvalue>
16812 </para></entry>
16813 </row>
16815 <row>
16816 <entry role="func_table_entry"><para role="func_signature">
16817 <indexterm>
16818 <primary>jsonb_path_exists_tz</primary>
16819 </indexterm>
16820 <function>jsonb_path_exists_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16821 <returnvalue>boolean</returnvalue>
16822 </para>
16823 <para role="func_signature">
16824 <indexterm>
16825 <primary>jsonb_path_match_tz</primary>
16826 </indexterm>
16827 <function>jsonb_path_match_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16828 <returnvalue>boolean</returnvalue>
16829 </para>
16830 <para role="func_signature">
16831 <indexterm>
16832 <primary>jsonb_path_query_tz</primary>
16833 </indexterm>
16834 <function>jsonb_path_query_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16835 <returnvalue>setof jsonb</returnvalue>
16836 </para>
16837 <para role="func_signature">
16838 <indexterm>
16839 <primary>jsonb_path_query_array_tz</primary>
16840 </indexterm>
16841 <function>jsonb_path_query_array_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16842 <returnvalue>jsonb</returnvalue>
16843 </para>
16844 <para role="func_signature">
16845 <indexterm>
16846 <primary>jsonb_path_query_first_tz</primary>
16847 </indexterm>
16848 <function>jsonb_path_query_first_tz</function> ( <parameter>target</parameter> <type>jsonb</type>, <parameter>path</parameter> <type>jsonpath</type> <optional>, <parameter>vars</parameter> <type>jsonb</type> <optional>, <parameter>silent</parameter> <type>boolean</type> </optional></optional> )
16849 <returnvalue>jsonb</returnvalue>
16850 </para>
16851 <para>
16852 These functions act like their counterparts described above without
16853 the <literal>_tz</literal> suffix, except that these functions support
16854 comparisons of date/time values that require timezone-aware
16855 conversions. The example below requires interpretation of the
16856 date-only value <literal>2015-08-02</literal> as a timestamp with time
16857 zone, so the result depends on the current
16858 <xref linkend="guc-timezone"/> setting. Due to this dependency, these
16859 functions are marked as stable, which means these functions cannot be
16860 used in indexes. Their counterparts are immutable, and so can be used
16861 in indexes; but they will throw errors if asked to make such
16862 comparisons.
16863 </para>
16864 <para>
16865 <literal>jsonb_path_exists_tz('["2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime() &lt; "2015-08-02".datetime())')</literal>
16866 <returnvalue>t</returnvalue>
16867 </para></entry>
16868 </row>
16870 <row>
16871 <entry role="func_table_entry"><para role="func_signature">
16872 <indexterm>
16873 <primary>jsonb_pretty</primary>
16874 </indexterm>
16875 <function>jsonb_pretty</function> ( <type>jsonb</type> )
16876 <returnvalue>text</returnvalue>
16877 </para>
16878 <para>
16879 Converts the given JSON value to pretty-printed, indented text.
16880 </para>
16881 <para>
16882 <literal>jsonb_pretty('[{"f1":1,"f2":null}, 2]')</literal>
16883 <returnvalue></returnvalue>
16884 <programlisting>
16887 "f1": 1,
16888 "f2": null
16892 </programlisting>
16893 </para></entry>
16894 </row>
16896 <row>
16897 <entry role="func_table_entry"><para role="func_signature">
16898 <indexterm>
16899 <primary>json_typeof</primary>
16900 </indexterm>
16901 <function>json_typeof</function> ( <type>json</type> )
16902 <returnvalue>text</returnvalue>
16903 </para>
16904 <para role="func_signature">
16905 <indexterm>
16906 <primary>jsonb_typeof</primary>
16907 </indexterm>
16908 <function>jsonb_typeof</function> ( <type>jsonb</type> )
16909 <returnvalue>text</returnvalue>
16910 </para>
16911 <para>
16912 Returns the type of the top-level JSON value as a text string.
16913 Possible types are
16914 <literal>object</literal>, <literal>array</literal>,
16915 <literal>string</literal>, <literal>number</literal>,
16916 <literal>boolean</literal>, and <literal>null</literal>.
16917 (The <literal>null</literal> result should not be confused
16918 with an SQL NULL; see the examples.)
16919 </para>
16920 <para>
16921 <literal>json_typeof('-123.4')</literal>
16922 <returnvalue>number</returnvalue>
16923 </para>
16924 <para>
16925 <literal>json_typeof('null'::json)</literal>
16926 <returnvalue>null</returnvalue>
16927 </para>
16928 <para>
16929 <literal>json_typeof(NULL::json) IS NULL</literal>
16930 <returnvalue>t</returnvalue>
16931 </para></entry>
16932 </row>
16933 </tbody>
16934 </tgroup>
16935 </table>
16936 </sect2>
16938 <sect2 id="functions-sqljson-path">
16939 <title>The SQL/JSON Path Language</title>
16941 <indexterm zone="functions-sqljson-path">
16942 <primary>SQL/JSON path language</primary>
16943 </indexterm>
16945 <para>
16946 SQL/JSON path expressions specify the items to be retrieved
16947 from the JSON data, similar to XPath expressions used
16948 for SQL access to XML. In <productname>PostgreSQL</productname>,
16949 path expressions are implemented as the <type>jsonpath</type>
16950 data type and can use any elements described in
16951 <xref linkend="datatype-jsonpath"/>.
16952 </para>
16954 <para>
16955 JSON query functions and operators
16956 pass the provided path expression to the <firstterm>path engine</firstterm>
16957 for evaluation. If the expression matches the queried JSON data,
16958 the corresponding JSON item, or set of items, is returned.
16959 Path expressions are written in the SQL/JSON path language
16960 and can include arithmetic expressions and functions.
16961 </para>
16963 <para>
16964 A path expression consists of a sequence of elements allowed
16965 by the <type>jsonpath</type> data type.
16966 The path expression is normally evaluated from left to right, but
16967 you can use parentheses to change the order of operations.
16968 If the evaluation is successful, a sequence of JSON items is produced,
16969 and the evaluation result is returned to the JSON query function
16970 that completes the specified computation.
16971 </para>
16973 <para>
16974 To refer to the JSON value being queried (the
16975 <firstterm>context item</firstterm>), use the <literal>$</literal> variable
16976 in the path expression. It can be followed by one or more
16977 <link linkend="type-jsonpath-accessors">accessor operators</link>,
16978 which go down the JSON structure level by level to retrieve sub-items
16979 of the context item. Each operator that follows deals with the
16980 result of the previous evaluation step.
16981 </para>
16983 <para>
16984 For example, suppose you have some JSON data from a GPS tracker that you
16985 would like to parse, such as:
16986 <programlisting>
16988 "track": {
16989 "segments": [
16991 "location": [ 47.763, 13.4034 ],
16992 "start time": "2018-10-14 10:05:14",
16993 "HR": 73
16996 "location": [ 47.706, 13.2635 ],
16997 "start time": "2018-10-14 10:39:21",
16998 "HR": 135
17003 </programlisting>
17004 </para>
17006 <para>
17007 To retrieve the available track segments, you need to use the
17008 <literal>.<replaceable>key</replaceable></literal> accessor
17009 operator to descend through surrounding JSON objects:
17010 <programlisting>
17011 $.track.segments
17012 </programlisting>
17013 </para>
17015 <para>
17016 To retrieve the contents of an array, you typically use the
17017 <literal>[*]</literal> operator. For example,
17018 the following path will return the location coordinates for all
17019 the available track segments:
17020 <programlisting>
17021 $.track.segments[*].location
17022 </programlisting>
17023 </para>
17025 <para>
17026 To return the coordinates of the first segment only, you can
17027 specify the corresponding subscript in the <literal>[]</literal>
17028 accessor operator. Recall that JSON array indexes are 0-relative:
17029 <programlisting>
17030 $.track.segments[0].location
17031 </programlisting>
17032 </para>
17034 <para>
17035 The result of each path evaluation step can be processed
17036 by one or more <type>jsonpath</type> operators and methods
17037 listed in <xref linkend="functions-sqljson-path-operators"/>.
17038 Each method name must be preceded by a dot. For example,
17039 you can get the size of an array:
17040 <programlisting>
17041 $.track.segments.size()
17042 </programlisting>
17043 More examples of using <type>jsonpath</type> operators
17044 and methods within path expressions appear below in
17045 <xref linkend="functions-sqljson-path-operators"/>.
17046 </para>
17048 <para>
17049 When defining a path, you can also use one or more
17050 <firstterm>filter expressions</firstterm> that work similarly to the
17051 <literal>WHERE</literal> clause in SQL. A filter expression begins with
17052 a question mark and provides a condition in parentheses:
17054 <programlisting>
17055 ? (<replaceable>condition</replaceable>)
17056 </programlisting>
17057 </para>
17059 <para>
17060 Filter expressions must be written just after the path evaluation step
17061 to which they should apply. The result of that step is filtered to include
17062 only those items that satisfy the provided condition. SQL/JSON defines
17063 three-valued logic, so the condition can be <literal>true</literal>, <literal>false</literal>,
17064 or <literal>unknown</literal>. The <literal>unknown</literal> value
17065 plays the same role as SQL <literal>NULL</literal> and can be tested
17066 for with the <literal>is unknown</literal> predicate. Further path
17067 evaluation steps use only those items for which the filter expression
17068 returned <literal>true</literal>.
17069 </para>
17071 <para>
17072 The functions and operators that can be used in filter expressions are
17073 listed in <xref linkend="functions-sqljson-filter-ex-table"/>. Within a
17074 filter expression, the <literal>@</literal> variable denotes the value
17075 being filtered (i.e., one result of the preceding path step). You can
17076 write accessor operators after <literal>@</literal> to retrieve component
17077 items.
17078 </para>
17080 <para>
17081 For example, suppose you would like to retrieve all heart rate values higher
17082 than 130. You can achieve this using the following expression:
17083 <programlisting>
17084 $.track.segments[*].HR ? (@ &gt; 130)
17085 </programlisting>
17086 </para>
17088 <para>
17089 To get the start times of segments with such values, you have to
17090 filter out irrelevant segments before returning the start times, so the
17091 filter expression is applied to the previous step, and the path used
17092 in the condition is different:
17093 <programlisting>
17094 $.track.segments[*] ? (@.HR &gt; 130)."start time"
17095 </programlisting>
17096 </para>
17098 <para>
17099 You can use several filter expressions in sequence, if required. For
17100 example, the following expression selects start times of all segments that
17101 contain locations with relevant coordinates and high heart rate values:
17102 <programlisting>
17103 $.track.segments[*] ? (@.location[1] &lt; 13.4) ? (@.HR &gt; 130)."start time"
17104 </programlisting>
17105 </para>
17107 <para>
17108 Using filter expressions at different nesting levels is also allowed.
17109 The following example first filters all segments by location, and then
17110 returns high heart rate values for these segments, if available:
17111 <programlisting>
17112 $.track.segments[*] ? (@.location[1] &lt; 13.4).HR ? (@ &gt; 130)
17113 </programlisting>
17114 </para>
17116 <para>
17117 You can also nest filter expressions within each other:
17118 <programlisting>
17119 $.track ? (exists(@.segments[*] ? (@.HR &gt; 130))).segments.size()
17120 </programlisting>
17121 This expression returns the size of the track if it contains any
17122 segments with high heart rate values, or an empty sequence otherwise.
17123 </para>
17125 <para>
17126 <productname>PostgreSQL</productname>'s implementation of the SQL/JSON path
17127 language has the following deviations from the SQL/JSON standard:
17128 </para>
17130 <itemizedlist>
17131 <listitem>
17132 <para>
17133 A path expression can be a Boolean predicate, although the SQL/JSON
17134 standard allows predicates only in filters. This is necessary for
17135 implementation of the <literal>@@</literal> operator. For example,
17136 the following <type>jsonpath</type> expression is valid in
17137 <productname>PostgreSQL</productname>:
17138 <programlisting>
17139 $.track.segments[*].HR &lt; 70
17140 </programlisting>
17141 </para>
17142 </listitem>
17144 <listitem>
17145 <para>
17146 There are minor differences in the interpretation of regular
17147 expression patterns used in <literal>like_regex</literal> filters, as
17148 described in <xref linkend="jsonpath-regular-expressions"/>.
17149 </para>
17150 </listitem>
17151 </itemizedlist>
17153 <sect3 id="strict-and-lax-modes">
17154 <title>Strict and Lax Modes</title>
17155 <para>
17156 When you query JSON data, the path expression may not match the
17157 actual JSON data structure. An attempt to access a non-existent
17158 member of an object or element of an array results in a
17159 structural error. SQL/JSON path expressions have two modes
17160 of handling structural errors:
17161 </para>
17163 <itemizedlist>
17164 <listitem>
17165 <para>
17166 lax (default) &mdash; the path engine implicitly adapts
17167 the queried data to the specified path.
17168 Any remaining structural errors are suppressed and converted
17169 to empty SQL/JSON sequences.
17170 </para>
17171 </listitem>
17172 <listitem>
17173 <para>
17174 strict &mdash; if a structural error occurs, an error is raised.
17175 </para>
17176 </listitem>
17177 </itemizedlist>
17179 <para>
17180 The lax mode facilitates matching of a JSON document structure and path
17181 expression if the JSON data does not conform to the expected schema.
17182 If an operand does not match the requirements of a particular operation,
17183 it can be automatically wrapped as an SQL/JSON array or unwrapped by
17184 converting its elements into an SQL/JSON sequence before performing
17185 this operation. Besides, comparison operators automatically unwrap their
17186 operands in the lax mode, so you can compare SQL/JSON arrays
17187 out-of-the-box. An array of size 1 is considered equal to its sole element.
17188 Automatic unwrapping is not performed only when:
17189 <itemizedlist>
17190 <listitem>
17191 <para>
17192 The path expression contains <literal>type()</literal> or
17193 <literal>size()</literal> methods that return the type
17194 and the number of elements in the array, respectively.
17195 </para>
17196 </listitem>
17197 <listitem>
17198 <para>
17199 The queried JSON data contain nested arrays. In this case, only
17200 the outermost array is unwrapped, while all the inner arrays
17201 remain unchanged. Thus, implicit unwrapping can only go one
17202 level down within each path evaluation step.
17203 </para>
17204 </listitem>
17205 </itemizedlist>
17206 </para>
17208 <para>
17209 For example, when querying the GPS data listed above, you can
17210 abstract from the fact that it stores an array of segments
17211 when using the lax mode:
17212 <programlisting>
17213 lax $.track.segments.location
17214 </programlisting>
17215 </para>
17217 <para>
17218 In the strict mode, the specified path must exactly match the structure of
17219 the queried JSON document to return an SQL/JSON item, so using this
17220 path expression will cause an error. To get the same result as in
17221 the lax mode, you have to explicitly unwrap the
17222 <literal>segments</literal> array:
17223 <programlisting>
17224 strict $.track.segments[*].location
17225 </programlisting>
17226 </para>
17228 <para>
17229 The <literal>.**</literal> accessor can lead to surprising results
17230 when using the lax mode. For instance, the following query selects every
17231 <literal>HR</literal> value twice:
17232 <programlisting>
17233 lax $.**.HR
17234 </programlisting>
17235 This happens because the <literal>.**</literal> accessor selects both
17236 the <literal>segments</literal> array and each of its elements, while
17237 the <literal>.HR</literal> accessor automatically unwraps arrays when
17238 using the lax mode. To avoid surprising results, we recommend using
17239 the <literal>.**</literal> accessor only in the strict mode. The
17240 following query selects each <literal>HR</literal> value just once:
17241 <programlisting>
17242 strict $.**.HR
17243 </programlisting>
17244 </para>
17246 </sect3>
17248 <sect3 id="functions-sqljson-path-operators">
17249 <title>SQL/JSON Path Operators and Methods</title>
17251 <para>
17252 <xref linkend="functions-sqljson-op-table"/> shows the operators and
17253 methods available in <type>jsonpath</type>. Note that while the unary
17254 operators and methods can be applied to multiple values resulting from a
17255 preceding path step, the binary operators (addition etc.) can only be
17256 applied to single values.
17257 </para>
17259 <table id="functions-sqljson-op-table">
17260 <title><type>jsonpath</type> Operators and Methods</title>
17261 <tgroup cols="1">
17262 <thead>
17263 <row>
17264 <entry role="func_table_entry"><para role="func_signature">
17265 Operator/Method
17266 </para>
17267 <para>
17268 Description
17269 </para>
17270 <para>
17271 Example(s)
17272 </para></entry>
17273 </row>
17274 </thead>
17276 <tbody>
17277 <row>
17278 <entry role="func_table_entry"><para role="func_signature">
17279 <replaceable>number</replaceable> <literal>+</literal> <replaceable>number</replaceable>
17280 <returnvalue><replaceable>number</replaceable></returnvalue>
17281 </para>
17282 <para>
17283 Addition
17284 </para>
17285 <para>
17286 <literal>jsonb_path_query('[2]', '$[0] + 3')</literal>
17287 <returnvalue>5</returnvalue>
17288 </para></entry>
17289 </row>
17291 <row>
17292 <entry role="func_table_entry"><para role="func_signature">
17293 <literal>+</literal> <replaceable>number</replaceable>
17294 <returnvalue><replaceable>number</replaceable></returnvalue>
17295 </para>
17296 <para>
17297 Unary plus (no operation); unlike addition, this can iterate over
17298 multiple values
17299 </para>
17300 <para>
17301 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '+ $.x')</literal>
17302 <returnvalue>[2, 3, 4]</returnvalue>
17303 </para></entry>
17304 </row>
17306 <row>
17307 <entry role="func_table_entry"><para role="func_signature">
17308 <replaceable>number</replaceable> <literal>-</literal> <replaceable>number</replaceable>
17309 <returnvalue><replaceable>number</replaceable></returnvalue>
17310 </para>
17311 <para>
17312 Subtraction
17313 </para>
17314 <para>
17315 <literal>jsonb_path_query('[2]', '7 - $[0]')</literal>
17316 <returnvalue>5</returnvalue>
17317 </para></entry>
17318 </row>
17320 <row>
17321 <entry role="func_table_entry"><para role="func_signature">
17322 <literal>-</literal> <replaceable>number</replaceable>
17323 <returnvalue><replaceable>number</replaceable></returnvalue>
17324 </para>
17325 <para>
17326 Negation; unlike subtraction, this can iterate over
17327 multiple values
17328 </para>
17329 <para>
17330 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '- $.x')</literal>
17331 <returnvalue>[-2, -3, -4]</returnvalue>
17332 </para></entry>
17333 </row>
17335 <row>
17336 <entry role="func_table_entry"><para role="func_signature">
17337 <replaceable>number</replaceable> <literal>*</literal> <replaceable>number</replaceable>
17338 <returnvalue><replaceable>number</replaceable></returnvalue>
17339 </para>
17340 <para>
17341 Multiplication
17342 </para>
17343 <para>
17344 <literal>jsonb_path_query('[4]', '2 * $[0]')</literal>
17345 <returnvalue>8</returnvalue>
17346 </para></entry>
17347 </row>
17349 <row>
17350 <entry role="func_table_entry"><para role="func_signature">
17351 <replaceable>number</replaceable> <literal>/</literal> <replaceable>number</replaceable>
17352 <returnvalue><replaceable>number</replaceable></returnvalue>
17353 </para>
17354 <para>
17355 Division
17356 </para>
17357 <para>
17358 <literal>jsonb_path_query('[8.5]', '$[0] / 2')</literal>
17359 <returnvalue>4.2500000000000000</returnvalue>
17360 </para></entry>
17361 </row>
17363 <row>
17364 <entry role="func_table_entry"><para role="func_signature">
17365 <replaceable>number</replaceable> <literal>%</literal> <replaceable>number</replaceable>
17366 <returnvalue><replaceable>number</replaceable></returnvalue>
17367 </para>
17368 <para>
17369 Modulo (remainder)
17370 </para>
17371 <para>
17372 <literal>jsonb_path_query('[32]', '$[0] % 10')</literal>
17373 <returnvalue>2</returnvalue>
17374 </para></entry>
17375 </row>
17377 <row>
17378 <entry role="func_table_entry"><para role="func_signature">
17379 <replaceable>value</replaceable> <literal>.</literal> <literal>type()</literal>
17380 <returnvalue><replaceable>string</replaceable></returnvalue>
17381 </para>
17382 <para>
17383 Type of the JSON item (see <function>json_typeof</function>)
17384 </para>
17385 <para>
17386 <literal>jsonb_path_query_array('[1, "2", {}]', '$[*].type()')</literal>
17387 <returnvalue>["number", "string", "object"]</returnvalue>
17388 </para></entry>
17389 </row>
17391 <row>
17392 <entry role="func_table_entry"><para role="func_signature">
17393 <replaceable>value</replaceable> <literal>.</literal> <literal>size()</literal>
17394 <returnvalue><replaceable>number</replaceable></returnvalue>
17395 </para>
17396 <para>
17397 Size of the JSON item (number of array elements, or 1 if not an
17398 array)
17399 </para>
17400 <para>
17401 <literal>jsonb_path_query('{"m": [11, 15]}', '$.m.size()')</literal>
17402 <returnvalue>2</returnvalue>
17403 </para></entry>
17404 </row>
17406 <row>
17407 <entry role="func_table_entry"><para role="func_signature">
17408 <replaceable>value</replaceable> <literal>.</literal> <literal>double()</literal>
17409 <returnvalue><replaceable>number</replaceable></returnvalue>
17410 </para>
17411 <para>
17412 Approximate floating-point number converted from a JSON number or
17413 string
17414 </para>
17415 <para>
17416 <literal>jsonb_path_query('{"len": "1.9"}', '$.len.double() * 2')</literal>
17417 <returnvalue>3.8</returnvalue>
17418 </para></entry>
17419 </row>
17421 <row>
17422 <entry role="func_table_entry"><para role="func_signature">
17423 <replaceable>number</replaceable> <literal>.</literal> <literal>ceiling()</literal>
17424 <returnvalue><replaceable>number</replaceable></returnvalue>
17425 </para>
17426 <para>
17427 Nearest integer greater than or equal to the given number
17428 </para>
17429 <para>
17430 <literal>jsonb_path_query('{"h": 1.3}', '$.h.ceiling()')</literal>
17431 <returnvalue>2</returnvalue>
17432 </para></entry>
17433 </row>
17435 <row>
17436 <entry role="func_table_entry"><para role="func_signature">
17437 <replaceable>number</replaceable> <literal>.</literal> <literal>floor()</literal>
17438 <returnvalue><replaceable>number</replaceable></returnvalue>
17439 </para>
17440 <para>
17441 Nearest integer less than or equal to the given number
17442 </para>
17443 <para>
17444 <literal>jsonb_path_query('{"h": 1.7}', '$.h.floor()')</literal>
17445 <returnvalue>1</returnvalue>
17446 </para></entry>
17447 </row>
17449 <row>
17450 <entry role="func_table_entry"><para role="func_signature">
17451 <replaceable>number</replaceable> <literal>.</literal> <literal>abs()</literal>
17452 <returnvalue><replaceable>number</replaceable></returnvalue>
17453 </para>
17454 <para>
17455 Absolute value of the given number
17456 </para>
17457 <para>
17458 <literal>jsonb_path_query('{"z": -0.3}', '$.z.abs()')</literal>
17459 <returnvalue>0.3</returnvalue>
17460 </para></entry>
17461 </row>
17463 <row>
17464 <entry role="func_table_entry"><para role="func_signature">
17465 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime()</literal>
17466 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
17467 (see note)
17468 </para>
17469 <para>
17470 Date/time value converted from a string
17471 </para>
17472 <para>
17473 <literal>jsonb_path_query('["2015-8-1", "2015-08-12"]', '$[*] ? (@.datetime() &lt; "2015-08-2".datetime())')</literal>
17474 <returnvalue>"2015-8-1"</returnvalue>
17475 </para></entry>
17476 </row>
17478 <row>
17479 <entry role="func_table_entry"><para role="func_signature">
17480 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime(<replaceable>template</replaceable>)</literal>
17481 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
17482 (see note)
17483 </para>
17484 <para>
17485 Date/time value converted from a string using the
17486 specified <function>to_timestamp</function> template
17487 </para>
17488 <para>
17489 <literal>jsonb_path_query_array('["12:30", "18:40"]', '$[*].datetime("HH24:MI")')</literal>
17490 <returnvalue>["12:30:00", "18:40:00"]</returnvalue>
17491 </para></entry>
17492 </row>
17494 <row>
17495 <entry role="func_table_entry"><para role="func_signature">
17496 <replaceable>object</replaceable> <literal>.</literal> <literal>keyvalue()</literal>
17497 <returnvalue><replaceable>array</replaceable></returnvalue>
17498 </para>
17499 <para>
17500 The object's key-value pairs, represented as an array of objects
17501 containing three fields: <literal>"key"</literal>,
17502 <literal>"value"</literal>, and <literal>"id"</literal>;
17503 <literal>"id"</literal> is a unique identifier of the object the
17504 key-value pair belongs to
17505 </para>
17506 <para>
17507 <literal>jsonb_path_query_array('{"x": "20", "y": 32}', '$.keyvalue()')</literal>
17508 <returnvalue>[{"id": 0, "key": "x", "value": "20"}, {"id": 0, "key": "y", "value": 32}]</returnvalue>
17509 </para></entry>
17510 </row>
17511 </tbody>
17512 </tgroup>
17513 </table>
17515 <note>
17516 <para>
17517 The result type of the <literal>datetime()</literal> and
17518 <literal>datetime(<replaceable>template</replaceable>)</literal>
17519 methods can be <type>date</type>, <type>timetz</type>, <type>time</type>,
17520 <type>timestamptz</type>, or <type>timestamp</type>.
17521 Both methods determine their result type dynamically.
17522 </para>
17523 <para>
17524 The <literal>datetime()</literal> method sequentially tries to
17525 match its input string to the ISO formats
17526 for <type>date</type>, <type>timetz</type>, <type>time</type>,
17527 <type>timestamptz</type>, and <type>timestamp</type>. It stops on
17528 the first matching format and emits the corresponding data type.
17529 </para>
17530 <para>
17531 The <literal>datetime(<replaceable>template</replaceable>)</literal>
17532 method determines the result type according to the fields used in the
17533 provided template string.
17534 </para>
17535 <para>
17536 The <literal>datetime()</literal> and
17537 <literal>datetime(<replaceable>template</replaceable>)</literal> methods
17538 use the same parsing rules as the <literal>to_timestamp</literal> SQL
17539 function does (see <xref linkend="functions-formatting"/>), with three
17540 exceptions. First, these methods don't allow unmatched template
17541 patterns. Second, only the following separators are allowed in the
17542 template string: minus sign, period, solidus (slash), comma, apostrophe,
17543 semicolon, colon and space. Third, separators in the template string
17544 must exactly match the input string.
17545 </para>
17546 <para>
17547 If different date/time types need to be compared, an implicit cast is
17548 applied. A <type>date</type> value can be cast to <type>timestamp</type>
17549 or <type>timestamptz</type>, <type>timestamp</type> can be cast to
17550 <type>timestamptz</type>, and <type>time</type> to <type>timetz</type>.
17551 However, all but the first of these conversions depend on the current
17552 <xref linkend="guc-timezone"/> setting, and thus can only be performed
17553 within timezone-aware <type>jsonpath</type> functions.
17554 </para>
17555 </note>
17557 <para>
17558 <xref linkend="functions-sqljson-filter-ex-table"/> shows the available
17559 filter expression elements.
17560 </para>
17562 <table id="functions-sqljson-filter-ex-table">
17563 <title><type>jsonpath</type> Filter Expression Elements</title>
17564 <tgroup cols="1">
17565 <thead>
17566 <row>
17567 <entry role="func_table_entry"><para role="func_signature">
17568 Predicate/Value
17569 </para>
17570 <para>
17571 Description
17572 </para>
17573 <para>
17574 Example(s)
17575 </para></entry>
17576 </row>
17577 </thead>
17579 <tbody>
17580 <row>
17581 <entry role="func_table_entry"><para role="func_signature">
17582 <replaceable>value</replaceable> <literal>==</literal> <replaceable>value</replaceable>
17583 <returnvalue>boolean</returnvalue>
17584 </para>
17585 <para>
17586 Equality comparison (this, and the other comparison operators, work on
17587 all JSON scalar values)
17588 </para>
17589 <para>
17590 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == 1)')</literal>
17591 <returnvalue>[1, 1]</returnvalue>
17592 </para>
17593 <para>
17594 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == "a")')</literal>
17595 <returnvalue>["a"]</returnvalue>
17596 </para></entry>
17597 </row>
17599 <row>
17600 <entry role="func_table_entry"><para role="func_signature">
17601 <replaceable>value</replaceable> <literal>!=</literal> <replaceable>value</replaceable>
17602 <returnvalue>boolean</returnvalue>
17603 </para>
17604 <para role="func_signature">
17605 <replaceable>value</replaceable> <literal>&lt;&gt;</literal> <replaceable>value</replaceable>
17606 <returnvalue>boolean</returnvalue>
17607 </para>
17608 <para>
17609 Non-equality comparison
17610 </para>
17611 <para>
17612 <literal>jsonb_path_query_array('[1, 2, 1, 3]', '$[*] ? (@ != 1)')</literal>
17613 <returnvalue>[2, 3]</returnvalue>
17614 </para>
17615 <para>
17616 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;&gt; "b")')</literal>
17617 <returnvalue>["a", "c"]</returnvalue>
17618 </para></entry>
17619 </row>
17621 <row>
17622 <entry role="func_table_entry"><para role="func_signature">
17623 <replaceable>value</replaceable> <literal>&lt;</literal> <replaceable>value</replaceable>
17624 <returnvalue>boolean</returnvalue>
17625 </para>
17626 <para>
17627 Less-than comparison
17628 </para>
17629 <para>
17630 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &lt; 2)')</literal>
17631 <returnvalue>[1]</returnvalue>
17632 </para></entry>
17633 </row>
17635 <row>
17636 <entry role="func_table_entry"><para role="func_signature">
17637 <replaceable>value</replaceable> <literal>&lt;=</literal> <replaceable>value</replaceable>
17638 <returnvalue>boolean</returnvalue>
17639 </para>
17640 <para>
17641 Less-than-or-equal-to comparison
17642 </para>
17643 <para>
17644 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;= "b")')</literal>
17645 <returnvalue>["a", "b"]</returnvalue>
17646 </para></entry>
17647 </row>
17649 <row>
17650 <entry role="func_table_entry"><para role="func_signature">
17651 <replaceable>value</replaceable> <literal>&gt;</literal> <replaceable>value</replaceable>
17652 <returnvalue>boolean</returnvalue>
17653 </para>
17654 <para>
17655 Greater-than comparison
17656 </para>
17657 <para>
17658 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt; 2)')</literal>
17659 <returnvalue>[3]</returnvalue>
17660 </para></entry>
17661 </row>
17663 <row>
17664 <entry role="func_table_entry"><para role="func_signature">
17665 <replaceable>value</replaceable> <literal>&gt;=</literal> <replaceable>value</replaceable>
17666 <returnvalue>boolean</returnvalue>
17667 </para>
17668 <para>
17669 Greater-than-or-equal-to comparison
17670 </para>
17671 <para>
17672 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt;= 2)')</literal>
17673 <returnvalue>[2, 3]</returnvalue>
17674 </para></entry>
17675 </row>
17677 <row>
17678 <entry role="func_table_entry"><para role="func_signature">
17679 <literal>true</literal>
17680 <returnvalue>boolean</returnvalue>
17681 </para>
17682 <para>
17683 JSON constant <literal>true</literal>
17684 </para>
17685 <para>
17686 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == true)')</literal>
17687 <returnvalue>{"name": "Chris", "parent": true}</returnvalue>
17688 </para></entry>
17689 </row>
17691 <row>
17692 <entry role="func_table_entry"><para role="func_signature">
17693 <literal>false</literal>
17694 <returnvalue>boolean</returnvalue>
17695 </para>
17696 <para>
17697 JSON constant <literal>false</literal>
17698 </para>
17699 <para>
17700 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == false)')</literal>
17701 <returnvalue>{"name": "John", "parent": false}</returnvalue>
17702 </para></entry>
17703 </row>
17705 <row>
17706 <entry role="func_table_entry"><para role="func_signature">
17707 <literal>null</literal>
17708 <returnvalue><replaceable>value</replaceable></returnvalue>
17709 </para>
17710 <para>
17711 JSON constant <literal>null</literal> (note that, unlike in SQL,
17712 comparison to <literal>null</literal> works normally)
17713 </para>
17714 <para>
17715 <literal>jsonb_path_query('[{"name": "Mary", "job": null}, {"name": "Michael", "job": "driver"}]', '$[*] ? (@.job == null) .name')</literal>
17716 <returnvalue>"Mary"</returnvalue>
17717 </para></entry>
17718 </row>
17720 <row>
17721 <entry role="func_table_entry"><para role="func_signature">
17722 <replaceable>boolean</replaceable> <literal>&amp;&amp;</literal> <replaceable>boolean</replaceable>
17723 <returnvalue>boolean</returnvalue>
17724 </para>
17725 <para>
17726 Boolean AND
17727 </para>
17728 <para>
17729 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &gt; 1 &amp;&amp; @ &lt; 5)')</literal>
17730 <returnvalue>3</returnvalue>
17731 </para></entry>
17732 </row>
17734 <row>
17735 <entry role="func_table_entry"><para role="func_signature">
17736 <replaceable>boolean</replaceable> <literal>||</literal> <replaceable>boolean</replaceable>
17737 <returnvalue>boolean</returnvalue>
17738 </para>
17739 <para>
17740 Boolean OR
17741 </para>
17742 <para>
17743 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &lt; 1 || @ &gt; 5)')</literal>
17744 <returnvalue>7</returnvalue>
17745 </para></entry>
17746 </row>
17748 <row>
17749 <entry role="func_table_entry"><para role="func_signature">
17750 <literal>!</literal> <replaceable>boolean</replaceable>
17751 <returnvalue>boolean</returnvalue>
17752 </para>
17753 <para>
17754 Boolean NOT
17755 </para>
17756 <para>
17757 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (!(@ &lt; 5))')</literal>
17758 <returnvalue>7</returnvalue>
17759 </para></entry>
17760 </row>
17762 <row>
17763 <entry role="func_table_entry"><para role="func_signature">
17764 <replaceable>boolean</replaceable> <literal>is unknown</literal>
17765 <returnvalue>boolean</returnvalue>
17766 </para>
17767 <para>
17768 Tests whether a Boolean condition is <literal>unknown</literal>.
17769 </para>
17770 <para>
17771 <literal>jsonb_path_query('[-1, 2, 7, "foo"]', '$[*] ? ((@ > 0) is unknown)')</literal>
17772 <returnvalue>"foo"</returnvalue>
17773 </para></entry>
17774 </row>
17776 <row>
17777 <entry role="func_table_entry"><para role="func_signature">
17778 <replaceable>string</replaceable> <literal>like_regex</literal> <replaceable>string</replaceable> <optional> <literal>flag</literal> <replaceable>string</replaceable> </optional>
17779 <returnvalue>boolean</returnvalue>
17780 </para>
17781 <para>
17782 Tests whether the first operand matches the regular expression
17783 given by the second operand, optionally with modifications
17784 described by a string of <literal>flag</literal> characters (see
17785 <xref linkend="jsonpath-regular-expressions"/>).
17786 </para>
17787 <para>
17788 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c")')</literal>
17789 <returnvalue>["abc", "abdacb"]</returnvalue>
17790 </para>
17791 <para>
17792 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c" flag "i")')</literal>
17793 <returnvalue>["abc", "aBdC", "abdacb"]</returnvalue>
17794 </para></entry>
17795 </row>
17797 <row>
17798 <entry role="func_table_entry"><para role="func_signature">
17799 <replaceable>string</replaceable> <literal>starts with</literal> <replaceable>string</replaceable>
17800 <returnvalue>boolean</returnvalue>
17801 </para>
17802 <para>
17803 Tests whether the second operand is an initial substring of the first
17804 operand.
17805 </para>
17806 <para>
17807 <literal>jsonb_path_query('["John Smith", "Mary Stone", "Bob Johnson"]', '$[*] ? (@ starts with "John")')</literal>
17808 <returnvalue>"John Smith"</returnvalue>
17809 </para></entry>
17810 </row>
17812 <row>
17813 <entry role="func_table_entry"><para role="func_signature">
17814 <literal>exists</literal> <literal>(</literal> <replaceable>path_expression</replaceable> <literal>)</literal>
17815 <returnvalue>boolean</returnvalue>
17816 </para>
17817 <para>
17818 Tests whether a path expression matches at least one SQL/JSON item.
17819 Returns <literal>unknown</literal> if the path expression would result
17820 in an error; the second example uses this to avoid a no-such-key error
17821 in strict mode.
17822 </para>
17823 <para>
17824 <literal>jsonb_path_query('{"x": [1, 2], "y": [2, 4]}', 'strict $.* ? (exists (@ ? (@[*] &gt; 2)))')</literal>
17825 <returnvalue>[2, 4]</returnvalue>
17826 </para>
17827 <para>
17828 <literal>jsonb_path_query_array('{"value": 41}', 'strict $ ? (exists (@.name)) .name')</literal>
17829 <returnvalue>[]</returnvalue>
17830 </para></entry>
17831 </row>
17832 </tbody>
17833 </tgroup>
17834 </table>
17836 </sect3>
17838 <sect3 id="jsonpath-regular-expressions">
17839 <title>SQL/JSON Regular Expressions</title>
17841 <indexterm zone="jsonpath-regular-expressions">
17842 <primary><literal>LIKE_REGEX</literal></primary>
17843 <secondary>in SQL/JSON</secondary>
17844 </indexterm>
17846 <para>
17847 SQL/JSON path expressions allow matching text to a regular expression
17848 with the <literal>like_regex</literal> filter. For example, the
17849 following SQL/JSON path query would case-insensitively match all
17850 strings in an array that start with an English vowel:
17851 <programlisting>
17852 $[*] ? (@ like_regex "^[aeiou]" flag "i")
17853 </programlisting>
17854 </para>
17856 <para>
17857 The optional <literal>flag</literal> string may include one or more of
17858 the characters
17859 <literal>i</literal> for case-insensitive match,
17860 <literal>m</literal> to allow <literal>^</literal>
17861 and <literal>$</literal> to match at newlines,
17862 <literal>s</literal> to allow <literal>.</literal> to match a newline,
17863 and <literal>q</literal> to quote the whole pattern (reducing the
17864 behavior to a simple substring match).
17865 </para>
17867 <para>
17868 The SQL/JSON standard borrows its definition for regular expressions
17869 from the <literal>LIKE_REGEX</literal> operator, which in turn uses the
17870 XQuery standard. PostgreSQL does not currently support the
17871 <literal>LIKE_REGEX</literal> operator. Therefore,
17872 the <literal>like_regex</literal> filter is implemented using the
17873 POSIX regular expression engine described in
17874 <xref linkend="functions-posix-regexp"/>. This leads to various minor
17875 discrepancies from standard SQL/JSON behavior, which are cataloged in
17876 <xref linkend="posix-vs-xquery"/>.
17877 Note, however, that the flag-letter incompatibilities described there
17878 do not apply to SQL/JSON, as it translates the XQuery flag letters to
17879 match what the POSIX engine expects.
17880 </para>
17882 <para>
17883 Keep in mind that the pattern argument of <literal>like_regex</literal>
17884 is a JSON path string literal, written according to the rules given in
17885 <xref linkend="datatype-jsonpath"/>. This means in particular that any
17886 backslashes you want to use in the regular expression must be doubled.
17887 For example, to match string values of the root document that contain
17888 only digits:
17889 <programlisting>
17890 $.* ? (@ like_regex "^\\d+$")
17891 </programlisting>
17892 </para>
17893 </sect3>
17894 </sect2>
17895 </sect1>
17897 <sect1 id="functions-sequence">
17898 <title>Sequence Manipulation Functions</title>
17900 <indexterm>
17901 <primary>sequence</primary>
17902 </indexterm>
17904 <para>
17905 This section describes functions for operating on <firstterm>sequence
17906 objects</firstterm>, also called sequence generators or just sequences.
17907 Sequence objects are special single-row tables created with <xref
17908 linkend="sql-createsequence"/>.
17909 Sequence objects are commonly used to generate unique identifiers
17910 for rows of a table. The sequence functions, listed in <xref
17911 linkend="functions-sequence-table"/>, provide simple, multiuser-safe
17912 methods for obtaining successive sequence values from sequence
17913 objects.
17914 </para>
17916 <table id="functions-sequence-table">
17917 <title>Sequence Functions</title>
17918 <tgroup cols="1">
17919 <thead>
17920 <row>
17921 <entry role="func_table_entry"><para role="func_signature">
17922 Function
17923 </para>
17924 <para>
17925 Description
17926 </para></entry>
17927 </row>
17928 </thead>
17930 <tbody>
17931 <row>
17932 <entry role="func_table_entry"><para role="func_signature">
17933 <indexterm>
17934 <primary>nextval</primary>
17935 </indexterm>
17936 <function>nextval</function> ( <type>regclass</type> )
17937 <returnvalue>bigint</returnvalue>
17938 </para>
17939 <para>
17940 Advances the sequence object to its next value and returns that value.
17941 This is done atomically: even if multiple sessions
17942 execute <function>nextval</function> concurrently, each will safely
17943 receive a distinct sequence value.
17944 If the sequence object has been created with default parameters,
17945 successive <function>nextval</function> calls will return successive
17946 values beginning with 1. Other behaviors can be obtained by using
17947 appropriate parameters in the <xref linkend="sql-createsequence"/>
17948 command.
17949 </para>
17950 <para>
17951 This function requires <literal>USAGE</literal>
17952 or <literal>UPDATE</literal> privilege on the sequence.
17953 </para></entry>
17954 </row>
17956 <row>
17957 <entry role="func_table_entry"><para role="func_signature">
17958 <indexterm>
17959 <primary>setval</primary>
17960 </indexterm>
17961 <function>setval</function> ( <type>regclass</type>, <type>bigint</type> <optional>, <type>boolean</type> </optional> )
17962 <returnvalue>bigint</returnvalue>
17963 </para>
17964 <para>
17965 Sets the sequence object's current value, and optionally
17966 its <literal>is_called</literal> flag. The two-parameter
17967 form sets the sequence's <literal>last_value</literal> field to the
17968 specified value and sets its <literal>is_called</literal> field to
17969 <literal>true</literal>, meaning that the next
17970 <function>nextval</function> will advance the sequence before
17971 returning a value. The value that will be reported
17972 by <function>currval</function> is also set to the specified value.
17973 In the three-parameter form, <literal>is_called</literal> can be set
17974 to either <literal>true</literal>
17975 or <literal>false</literal>. <literal>true</literal> has the same
17976 effect as the two-parameter form. If it is set
17977 to <literal>false</literal>, the next <function>nextval</function>
17978 will return exactly the specified value, and sequence advancement
17979 commences with the following <function>nextval</function>.
17980 Furthermore, the value reported by <function>currval</function> is not
17981 changed in this case. For example,
17982 <programlisting>
17983 SELECT setval('myseq', 42); <lineannotation>Next <function>nextval</function> will return 43</lineannotation>
17984 SELECT setval('myseq', 42, true); <lineannotation>Same as above</lineannotation>
17985 SELECT setval('myseq', 42, false); <lineannotation>Next <function>nextval</function> will return 42</lineannotation>
17986 </programlisting>
17987 The result returned by <function>setval</function> is just the value of its
17988 second argument.
17989 </para>
17990 <para>
17991 This function requires <literal>UPDATE</literal> privilege on the
17992 sequence.
17993 </para></entry>
17994 </row>
17996 <row>
17997 <entry role="func_table_entry"><para role="func_signature">
17998 <indexterm>
17999 <primary>currval</primary>
18000 </indexterm>
18001 <function>currval</function> ( <type>regclass</type> )
18002 <returnvalue>bigint</returnvalue>
18003 </para>
18004 <para>
18005 Returns the value most recently obtained
18006 by <function>nextval</function> for this sequence in the current
18007 session. (An error is reported if <function>nextval</function> has
18008 never been called for this sequence in this session.) Because this is
18009 returning a session-local value, it gives a predictable answer whether
18010 or not other sessions have executed <function>nextval</function> since
18011 the current session did.
18012 </para>
18013 <para>
18014 This function requires <literal>USAGE</literal>
18015 or <literal>SELECT</literal> privilege on the sequence.
18016 </para></entry>
18017 </row>
18019 <row>
18020 <entry role="func_table_entry"><para role="func_signature">
18021 <indexterm>
18022 <primary>lastval</primary>
18023 </indexterm>
18024 <function>lastval</function> ()
18025 <returnvalue>bigint</returnvalue>
18026 </para>
18027 <para>
18028 Returns the value most recently returned by
18029 <function>nextval</function> in the current session. This function is
18030 identical to <function>currval</function>, except that instead
18031 of taking the sequence name as an argument it refers to whichever
18032 sequence <function>nextval</function> was most recently applied to
18033 in the current session. It is an error to call
18034 <function>lastval</function> if <function>nextval</function>
18035 has not yet been called in the current session.
18036 </para>
18037 <para>
18038 This function requires <literal>USAGE</literal>
18039 or <literal>SELECT</literal> privilege on the last used sequence.
18040 </para></entry>
18041 </row>
18042 </tbody>
18043 </tgroup>
18044 </table>
18046 <caution>
18047 <para>
18048 To avoid blocking concurrent transactions that obtain numbers from
18049 the same sequence, the value obtained by <function>nextval</function>
18050 is not reclaimed for re-use if the calling transaction later aborts.
18051 This means that transaction aborts or database crashes can result in
18052 gaps in the sequence of assigned values. That can happen without a
18053 transaction abort, too. For example an <command>INSERT</command> with
18054 an <literal>ON CONFLICT</literal> clause will compute the to-be-inserted
18055 tuple, including doing any required <function>nextval</function>
18056 calls, before detecting any conflict that would cause it to follow
18057 the <literal>ON CONFLICT</literal> rule instead.
18058 Thus, <productname>PostgreSQL</productname> sequence
18059 objects <emphasis>cannot be used to obtain <quote>gapless</quote>
18060 sequences</emphasis>.
18061 </para>
18063 <para>
18064 Likewise, sequence state changes made by <function>setval</function>
18065 are immediately visible to other transactions, and are not undone if
18066 the calling transaction rolls back.
18067 </para>
18069 <para>
18070 If the database cluster crashes before committing a transaction
18071 containing a <function>nextval</function>
18072 or <function>setval</function> call, the sequence state change might
18073 not have made its way to persistent storage, so that it is uncertain
18074 whether the sequence will have its original or updated state after the
18075 cluster restarts. This is harmless for usage of the sequence within
18076 the database, since other effects of uncommitted transactions will not
18077 be visible either. However, if you wish to use a sequence value for
18078 persistent outside-the-database purposes, make sure that the
18079 <function>nextval</function> call has been committed before doing so.
18080 </para>
18081 </caution>
18083 <para>
18084 The sequence to be operated on by a sequence function is specified by
18085 a <type>regclass</type> argument, which is simply the OID of the sequence in the
18086 <structname>pg_class</structname> system catalog. You do not have to look up the
18087 OID by hand, however, since the <type>regclass</type> data type's input
18088 converter will do the work for you. See <xref linkend="datatype-oid"/>
18089 for details.
18090 </para>
18091 </sect1>
18094 <sect1 id="functions-conditional">
18095 <title>Conditional Expressions</title>
18097 <indexterm>
18098 <primary>CASE</primary>
18099 </indexterm>
18101 <indexterm>
18102 <primary>conditional expression</primary>
18103 </indexterm>
18105 <para>
18106 This section describes the <acronym>SQL</acronym>-compliant conditional expressions
18107 available in <productname>PostgreSQL</productname>.
18108 </para>
18110 <tip>
18111 <para>
18112 If your needs go beyond the capabilities of these conditional
18113 expressions, you might want to consider writing a server-side function
18114 in a more expressive programming language.
18115 </para>
18116 </tip>
18118 <note>
18119 <para>
18120 Although <token>COALESCE</token>, <token>GREATEST</token>, and
18121 <token>LEAST</token> are syntactically similar to functions, they are
18122 not ordinary functions, and thus cannot be used with explicit
18123 <token>VARIADIC</token> array arguments.
18124 </para>
18125 </note>
18127 <sect2 id="functions-case">
18128 <title><literal>CASE</literal></title>
18130 <para>
18131 The <acronym>SQL</acronym> <token>CASE</token> expression is a
18132 generic conditional expression, similar to if/else statements in
18133 other programming languages:
18135 <synopsis>
18136 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
18137 <optional>WHEN ...</optional>
18138 <optional>ELSE <replaceable>result</replaceable></optional>
18140 </synopsis>
18142 <token>CASE</token> clauses can be used wherever
18143 an expression is valid. Each <replaceable>condition</replaceable> is an
18144 expression that returns a <type>boolean</type> result. If the condition's
18145 result is true, the value of the <token>CASE</token> expression is the
18146 <replaceable>result</replaceable> that follows the condition, and the
18147 remainder of the <token>CASE</token> expression is not processed. If the
18148 condition's result is not true, any subsequent <token>WHEN</token> clauses
18149 are examined in the same manner. If no <token>WHEN</token>
18150 <replaceable>condition</replaceable> yields true, the value of the
18151 <token>CASE</token> expression is the <replaceable>result</replaceable> of the
18152 <token>ELSE</token> clause. If the <token>ELSE</token> clause is
18153 omitted and no condition is true, the result is null.
18154 </para>
18156 <para>
18157 An example:
18158 <screen>
18159 SELECT * FROM test;
18168 SELECT a,
18169 CASE WHEN a=1 THEN 'one'
18170 WHEN a=2 THEN 'two'
18171 ELSE 'other'
18173 FROM test;
18175 a | case
18176 ---+-------
18177 1 | one
18178 2 | two
18179 3 | other
18180 </screen>
18181 </para>
18183 <para>
18184 The data types of all the <replaceable>result</replaceable>
18185 expressions must be convertible to a single output type.
18186 See <xref linkend="typeconv-union-case"/> for more details.
18187 </para>
18189 <para>
18190 There is a <quote>simple</quote> form of <token>CASE</token> expression
18191 that is a variant of the general form above:
18193 <synopsis>
18194 CASE <replaceable>expression</replaceable>
18195 WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
18196 <optional>WHEN ...</optional>
18197 <optional>ELSE <replaceable>result</replaceable></optional>
18199 </synopsis>
18201 The first
18202 <replaceable>expression</replaceable> is computed, then compared to
18203 each of the <replaceable>value</replaceable> expressions in the
18204 <token>WHEN</token> clauses until one is found that is equal to it. If
18205 no match is found, the <replaceable>result</replaceable> of the
18206 <token>ELSE</token> clause (or a null value) is returned. This is similar
18207 to the <function>switch</function> statement in C.
18208 </para>
18210 <para>
18211 The example above can be written using the simple
18212 <token>CASE</token> syntax:
18213 <screen>
18214 SELECT a,
18215 CASE a WHEN 1 THEN 'one'
18216 WHEN 2 THEN 'two'
18217 ELSE 'other'
18219 FROM test;
18221 a | case
18222 ---+-------
18223 1 | one
18224 2 | two
18225 3 | other
18226 </screen>
18227 </para>
18229 <para>
18230 A <token>CASE</token> expression does not evaluate any subexpressions
18231 that are not needed to determine the result. For example, this is a
18232 possible way of avoiding a division-by-zero failure:
18233 <programlisting>
18234 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
18235 </programlisting>
18236 </para>
18238 <note>
18239 <para>
18240 As described in <xref linkend="syntax-express-eval"/>, there are various
18241 situations in which subexpressions of an expression are evaluated at
18242 different times, so that the principle that <quote><token>CASE</token>
18243 evaluates only necessary subexpressions</quote> is not ironclad. For
18244 example a constant <literal>1/0</literal> subexpression will usually result in
18245 a division-by-zero failure at planning time, even if it's within
18246 a <token>CASE</token> arm that would never be entered at run time.
18247 </para>
18248 </note>
18249 </sect2>
18251 <sect2 id="functions-coalesce-nvl-ifnull">
18252 <title><literal>COALESCE</literal></title>
18254 <indexterm>
18255 <primary>COALESCE</primary>
18256 </indexterm>
18258 <indexterm>
18259 <primary>NVL</primary>
18260 </indexterm>
18262 <indexterm>
18263 <primary>IFNULL</primary>
18264 </indexterm>
18266 <synopsis>
18267 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18268 </synopsis>
18270 <para>
18271 The <function>COALESCE</function> function returns the first of its
18272 arguments that is not null. Null is returned only if all arguments
18273 are null. It is often used to substitute a default value for
18274 null values when data is retrieved for display, for example:
18275 <programlisting>
18276 SELECT COALESCE(description, short_description, '(none)') ...
18277 </programlisting>
18278 This returns <varname>description</varname> if it is not null, otherwise
18279 <varname>short_description</varname> if it is not null, otherwise <literal>(none)</literal>.
18280 </para>
18282 <para>
18283 The arguments must all be convertible to a common data type, which
18284 will be the type of the result (see
18285 <xref linkend="typeconv-union-case"/> for details).
18286 </para>
18288 <para>
18289 Like a <token>CASE</token> expression, <function>COALESCE</function> only
18290 evaluates the arguments that are needed to determine the result;
18291 that is, arguments to the right of the first non-null argument are
18292 not evaluated. This SQL-standard function provides capabilities similar
18293 to <function>NVL</function> and <function>IFNULL</function>, which are used in some other
18294 database systems.
18295 </para>
18296 </sect2>
18298 <sect2 id="functions-nullif">
18299 <title><literal>NULLIF</literal></title>
18301 <indexterm>
18302 <primary>NULLIF</primary>
18303 </indexterm>
18305 <synopsis>
18306 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
18307 </synopsis>
18309 <para>
18310 The <function>NULLIF</function> function returns a null value if
18311 <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
18312 otherwise it returns <replaceable>value1</replaceable>.
18313 This can be used to perform the inverse operation of the
18314 <function>COALESCE</function> example given above:
18315 <programlisting>
18316 SELECT NULLIF(value, '(none)') ...
18317 </programlisting>
18318 In this example, if <literal>value</literal> is <literal>(none)</literal>,
18319 null is returned, otherwise the value of <literal>value</literal>
18320 is returned.
18321 </para>
18323 <para>
18324 The two arguments must be of comparable types.
18325 To be specific, they are compared exactly as if you had
18326 written <literal><replaceable>value1</replaceable>
18327 = <replaceable>value2</replaceable></literal>, so there must be a
18328 suitable <literal>=</literal> operator available.
18329 </para>
18331 <para>
18332 The result has the same type as the first argument &mdash; but there is
18333 a subtlety. What is actually returned is the first argument of the
18334 implied <literal>=</literal> operator, and in some cases that will have
18335 been promoted to match the second argument's type. For
18336 example, <literal>NULLIF(1, 2.2)</literal> yields <type>numeric</type>,
18337 because there is no <type>integer</type> <literal>=</literal>
18338 <type>numeric</type> operator,
18339 only <type>numeric</type> <literal>=</literal> <type>numeric</type>.
18340 </para>
18342 </sect2>
18344 <sect2 id="functions-greatest-least">
18345 <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
18347 <indexterm>
18348 <primary>GREATEST</primary>
18349 </indexterm>
18350 <indexterm>
18351 <primary>LEAST</primary>
18352 </indexterm>
18354 <synopsis>
18355 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18356 </synopsis>
18357 <synopsis>
18358 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18359 </synopsis>
18361 <para>
18362 The <function>GREATEST</function> and <function>LEAST</function> functions select the
18363 largest or smallest value from a list of any number of expressions.
18364 The expressions must all be convertible to a common data type, which
18365 will be the type of the result
18366 (see <xref linkend="typeconv-union-case"/> for details).
18367 </para>
18369 <para>
18370 NULL values in the argument list are ignored. The result will be NULL
18371 only if all the expressions evaluate to NULL. (This is a deviation from
18372 the SQL standard. According to the standard, the return value is NULL if
18373 any argument is NULL. Some other databases behave this way.)
18374 </para>
18375 </sect2>
18376 </sect1>
18378 <sect1 id="functions-array">
18379 <title>Array Functions and Operators</title>
18381 <para>
18382 <xref linkend="array-operators-table"/> shows the specialized operators
18383 available for array types.
18384 In addition to those, the usual comparison operators shown in <xref
18385 linkend="functions-comparison-op-table"/> are available for
18386 arrays. The comparison operators compare the array contents
18387 element-by-element, using the default B-tree comparison function for
18388 the element data type, and sort based on the first difference.
18389 In multidimensional arrays the elements are visited in row-major order
18390 (last subscript varies most rapidly).
18391 If the contents of two arrays are equal but the dimensionality is
18392 different, the first difference in the dimensionality information
18393 determines the sort order.
18394 </para>
18396 <table id="array-operators-table">
18397 <title>Array Operators</title>
18398 <tgroup cols="1">
18399 <thead>
18400 <row>
18401 <entry role="func_table_entry"><para role="func_signature">
18402 Operator
18403 </para>
18404 <para>
18405 Description
18406 </para>
18407 <para>
18408 Example(s)
18409 </para></entry>
18410 </row>
18411 </thead>
18413 <tbody>
18414 <row>
18415 <entry role="func_table_entry"><para role="func_signature">
18416 <type>anyarray</type> <literal>@&gt;</literal> <type>anyarray</type>
18417 <returnvalue>boolean</returnvalue>
18418 </para>
18419 <para>
18420 Does the first array contain the second, that is, does each element
18421 appearing in the second array equal some element of the first array?
18422 (Duplicates are not treated specially,
18423 thus <literal>ARRAY[1]</literal> and <literal>ARRAY[1,1]</literal> are
18424 each considered to contain the other.)
18425 </para>
18426 <para>
18427 <literal>ARRAY[1,4,3] @&gt; ARRAY[3,1,3]</literal>
18428 <returnvalue>t</returnvalue>
18429 </para></entry>
18430 </row>
18432 <row>
18433 <entry role="func_table_entry"><para role="func_signature">
18434 <type>anyarray</type> <literal>&lt;@</literal> <type>anyarray</type>
18435 <returnvalue>boolean</returnvalue>
18436 </para>
18437 <para>
18438 Is the first array contained by the second?
18439 </para>
18440 <para>
18441 <literal>ARRAY[2,2,7] &lt;@ ARRAY[1,7,4,2,6]</literal>
18442 <returnvalue>t</returnvalue>
18443 </para></entry>
18444 </row>
18446 <row>
18447 <entry role="func_table_entry"><para role="func_signature">
18448 <type>anyarray</type> <literal>&amp;&amp;</literal> <type>anyarray</type>
18449 <returnvalue>boolean</returnvalue>
18450 </para>
18451 <para>
18452 Do the arrays overlap, that is, have any elements in common?
18453 </para>
18454 <para>
18455 <literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal>
18456 <returnvalue>t</returnvalue>
18457 </para></entry>
18458 </row>
18460 <row>
18461 <entry role="func_table_entry"><para role="func_signature">
18462 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
18463 <returnvalue>anycompatiblearray</returnvalue>
18464 </para>
18465 <para>
18466 Concatenates the two arrays. Concatenating a null or empty array is a
18467 no-op; otherwise the arrays must have the same number of dimensions
18468 (as illustrated by the first example) or differ in number of
18469 dimensions by one (as illustrated by the second).
18470 If the arrays are not of identical element types, they will be coerced
18471 to a common type (see <xref linkend="typeconv-union-case"/>).
18472 </para>
18473 <para>
18474 <literal>ARRAY[1,2,3] || ARRAY[4,5,6,7]</literal>
18475 <returnvalue>{1,2,3,4,5,6,7}</returnvalue>
18476 </para>
18477 <para>
18478 <literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9.9]]</literal>
18479 <returnvalue>{{1,2,3},{4,5,6},{7,8,9.9}}</returnvalue>
18480 </para></entry>
18481 </row>
18483 <row>
18484 <entry role="func_table_entry"><para role="func_signature">
18485 <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
18486 <returnvalue>anycompatiblearray</returnvalue>
18487 </para>
18488 <para>
18489 Concatenates an element onto the front of an array (which must be
18490 empty or one-dimensional).
18491 </para>
18492 <para>
18493 <literal>3 || ARRAY[4,5,6]</literal>
18494 <returnvalue>{3,4,5,6}</returnvalue>
18495 </para></entry>
18496 </row>
18498 <row>
18499 <entry role="func_table_entry"><para role="func_signature">
18500 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
18501 <returnvalue>anycompatiblearray</returnvalue>
18502 </para>
18503 <para>
18504 Concatenates an element onto the end of an array (which must be
18505 empty or one-dimensional).
18506 </para>
18507 <para>
18508 <literal>ARRAY[4,5,6] || 7</literal>
18509 <returnvalue>{4,5,6,7}</returnvalue>
18510 </para></entry>
18511 </row>
18512 </tbody>
18513 </tgroup>
18514 </table>
18516 <para>
18517 See <xref linkend="arrays"/> for more details about array operator
18518 behavior. See <xref linkend="indexes-types"/> for more details about
18519 which operators support indexed operations.
18520 </para>
18522 <para>
18523 <xref linkend="array-functions-table"/> shows the functions
18524 available for use with array types. See <xref linkend="arrays"/>
18525 for more information and examples of the use of these functions.
18526 </para>
18528 <table id="array-functions-table">
18529 <title>Array Functions</title>
18530 <tgroup cols="1">
18531 <thead>
18532 <row>
18533 <entry role="func_table_entry"><para role="func_signature">
18534 Function
18535 </para>
18536 <para>
18537 Description
18538 </para>
18539 <para>
18540 Example(s)
18541 </para></entry>
18542 </row>
18543 </thead>
18545 <tbody>
18546 <row>
18547 <entry role="func_table_entry"><para role="func_signature">
18548 <indexterm>
18549 <primary>array_append</primary>
18550 </indexterm>
18551 <function>array_append</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
18552 <returnvalue>anycompatiblearray</returnvalue>
18553 </para>
18554 <para>
18555 Appends an element to the end of an array (same as
18556 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
18557 operator).
18558 </para>
18559 <para>
18560 <literal>array_append(ARRAY[1,2], 3)</literal>
18561 <returnvalue>{1,2,3}</returnvalue>
18562 </para></entry>
18563 </row>
18565 <row>
18566 <entry role="func_table_entry"><para role="func_signature">
18567 <indexterm>
18568 <primary>array_cat</primary>
18569 </indexterm>
18570 <function>array_cat</function> ( <type>anycompatiblearray</type>, <type>anycompatiblearray</type> )
18571 <returnvalue>anycompatiblearray</returnvalue>
18572 </para>
18573 <para>
18574 Concatenates two arrays (same as
18575 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
18576 operator).
18577 </para>
18578 <para>
18579 <literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal>
18580 <returnvalue>{1,2,3,4,5}</returnvalue>
18581 </para></entry>
18582 </row>
18584 <row>
18585 <entry role="func_table_entry"><para role="func_signature">
18586 <indexterm>
18587 <primary>array_dims</primary>
18588 </indexterm>
18589 <function>array_dims</function> ( <type>anyarray</type> )
18590 <returnvalue>text</returnvalue>
18591 </para>
18592 <para>
18593 Returns a text representation of the array's dimensions.
18594 </para>
18595 <para>
18596 <literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal>
18597 <returnvalue>[1:2][1:3]</returnvalue>
18598 </para></entry>
18599 </row>
18601 <row>
18602 <entry role="func_table_entry"><para role="func_signature">
18603 <indexterm>
18604 <primary>array_fill</primary>
18605 </indexterm>
18606 <function>array_fill</function> ( <type>anyelement</type>, <type>integer[]</type>
18607 <optional>, <type>integer[]</type> </optional> )
18608 <returnvalue>anyarray</returnvalue>
18609 </para>
18610 <para>
18611 Returns an array filled with copies of the given value, having
18612 dimensions of the lengths specified by the second argument.
18613 The optional third argument supplies lower-bound values for each
18614 dimension (which default to all <literal>1</literal>).
18615 </para>
18616 <para>
18617 <literal>array_fill(11, ARRAY[2,3])</literal>
18618 <returnvalue>{{11,11,11},{11,11,11}}</returnvalue>
18619 </para>
18620 <para>
18621 <literal>array_fill(7, ARRAY[3], ARRAY[2])</literal>
18622 <returnvalue>[2:4]={7,7,7}</returnvalue>
18623 </para></entry>
18624 </row>
18626 <row>
18627 <entry role="func_table_entry"><para role="func_signature">
18628 <indexterm>
18629 <primary>array_length</primary>
18630 </indexterm>
18631 <function>array_length</function> ( <type>anyarray</type>, <type>integer</type> )
18632 <returnvalue>integer</returnvalue>
18633 </para>
18634 <para>
18635 Returns the length of the requested array dimension.
18636 (Produces NULL instead of 0 for empty or missing array dimensions.)
18637 </para>
18638 <para>
18639 <literal>array_length(array[1,2,3], 1)</literal>
18640 <returnvalue>3</returnvalue>
18641 </para>
18642 <para>
18643 <literal>array_length(array[]::int[], 1)</literal>
18644 <returnvalue>NULL</returnvalue>
18645 </para>
18646 <para>
18647 <literal>array_length(array['text'], 2)</literal>
18648 <returnvalue>NULL</returnvalue>
18649 </para></entry>
18650 </row>
18652 <row>
18653 <entry role="func_table_entry"><para role="func_signature">
18654 <indexterm>
18655 <primary>array_lower</primary>
18656 </indexterm>
18657 <function>array_lower</function> ( <type>anyarray</type>, <type>integer</type> )
18658 <returnvalue>integer</returnvalue>
18659 </para>
18660 <para>
18661 Returns the lower bound of the requested array dimension.
18662 </para>
18663 <para>
18664 <literal>array_lower('[0:2]={1,2,3}'::integer[], 1)</literal>
18665 <returnvalue>0</returnvalue>
18666 </para></entry>
18667 </row>
18669 <row>
18670 <entry role="func_table_entry"><para role="func_signature">
18671 <indexterm>
18672 <primary>array_ndims</primary>
18673 </indexterm>
18674 <function>array_ndims</function> ( <type>anyarray</type> )
18675 <returnvalue>integer</returnvalue>
18676 </para>
18677 <para>
18678 Returns the number of dimensions of the array.
18679 </para>
18680 <para>
18681 <literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal>
18682 <returnvalue>2</returnvalue>
18683 </para></entry>
18684 </row>
18686 <row>
18687 <entry role="func_table_entry"><para role="func_signature">
18688 <indexterm>
18689 <primary>array_position</primary>
18690 </indexterm>
18691 <function>array_position</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> <optional>, <type>integer</type> </optional> )
18692 <returnvalue>integer</returnvalue>
18693 </para>
18694 <para>
18695 Returns the subscript of the first occurrence of the second argument
18696 in the array, or <literal>NULL</literal> if it's not present.
18697 If the third argument is given, the search begins at that subscript.
18698 The array must be one-dimensional.
18699 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
18700 semantics, so it is possible to search for <literal>NULL</literal>.
18701 </para>
18702 <para>
18703 <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')</literal>
18704 <returnvalue>2</returnvalue>
18705 </para></entry>
18706 </row>
18708 <row>
18709 <entry role="func_table_entry"><para role="func_signature">
18710 <indexterm>
18711 <primary>array_positions</primary>
18712 </indexterm>
18713 <function>array_positions</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
18714 <returnvalue>integer[]</returnvalue>
18715 </para>
18716 <para>
18717 Returns an array of the subscripts of all occurrences of the second
18718 argument in the array given as first argument.
18719 The array must be one-dimensional.
18720 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
18721 semantics, so it is possible to search for <literal>NULL</literal>.
18722 <literal>NULL</literal> is returned only if the array
18723 is <literal>NULL</literal>; if the value is not found in the array, an
18724 empty array is returned.
18725 </para>
18726 <para>
18727 <literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal>
18728 <returnvalue>{1,2,4}</returnvalue>
18729 </para></entry>
18730 </row>
18732 <row>
18733 <entry role="func_table_entry"><para role="func_signature">
18734 <indexterm>
18735 <primary>array_prepend</primary>
18736 </indexterm>
18737 <function>array_prepend</function> ( <type>anycompatible</type>, <type>anycompatiblearray</type> )
18738 <returnvalue>anycompatiblearray</returnvalue>
18739 </para>
18740 <para>
18741 Prepends an element to the beginning of an array (same as
18742 the <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
18743 operator).
18744 </para>
18745 <para>
18746 <literal>array_prepend(1, ARRAY[2,3])</literal>
18747 <returnvalue>{1,2,3}</returnvalue>
18748 </para></entry>
18749 </row>
18751 <row>
18752 <entry role="func_table_entry"><para role="func_signature">
18753 <indexterm>
18754 <primary>array_remove</primary>
18755 </indexterm>
18756 <function>array_remove</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
18757 <returnvalue>anycompatiblearray</returnvalue>
18758 </para>
18759 <para>
18760 Removes all elements equal to the given value from the array.
18761 The array must be one-dimensional.
18762 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
18763 semantics, so it is possible to remove <literal>NULL</literal>s.
18764 </para>
18765 <para>
18766 <literal>array_remove(ARRAY[1,2,3,2], 2)</literal>
18767 <returnvalue>{1,3}</returnvalue>
18768 </para></entry>
18769 </row>
18771 <row>
18772 <entry role="func_table_entry"><para role="func_signature">
18773 <indexterm>
18774 <primary>array_replace</primary>
18775 </indexterm>
18776 <function>array_replace</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type>, <type>anycompatible</type> )
18777 <returnvalue>anycompatiblearray</returnvalue>
18778 </para>
18779 <para>
18780 Replaces each array element equal to the second argument with the
18781 third argument.
18782 </para>
18783 <para>
18784 <literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal>
18785 <returnvalue>{1,2,3,4}</returnvalue>
18786 </para></entry>
18787 </row>
18789 <row>
18790 <entry role="func_table_entry"><para role="func_signature">
18791 <indexterm>
18792 <primary>array_sample</primary>
18793 </indexterm>
18794 <function>array_sample</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
18795 <returnvalue>anyarray</returnvalue>
18796 </para>
18797 <para>
18798 Returns an array of <parameter>n</parameter> items randomly selected
18799 from <parameter>array</parameter>. <parameter>n</parameter> may not
18800 exceed the length of <parameter>array</parameter>'s first dimension.
18801 If <parameter>array</parameter> is multi-dimensional,
18802 an <quote>item</quote> is a slice having a given first subscript.
18803 </para>
18804 <para>
18805 <literal>array_sample(ARRAY[1,2,3,4,5,6], 3)</literal>
18806 <returnvalue>{2,6,1}</returnvalue>
18807 </para>
18808 <para>
18809 <literal>array_sample(ARRAY[[1,2],[3,4],[5,6]], 2)</literal>
18810 <returnvalue>{{5,6},{1,2}}</returnvalue>
18811 </para></entry>
18812 </row>
18814 <row>
18815 <entry role="func_table_entry"><para role="func_signature">
18816 <indexterm>
18817 <primary>array_shuffle</primary>
18818 </indexterm>
18819 <function>array_shuffle</function> ( <type>anyarray</type> )
18820 <returnvalue>anyarray</returnvalue>
18821 </para>
18822 <para>
18823 Randomly shuffles the first dimension of the array.
18824 </para>
18825 <para>
18826 <literal>array_shuffle(ARRAY[[1,2],[3,4],[5,6]])</literal>
18827 <returnvalue>{{5,6},{1,2},{3,4}}</returnvalue>
18828 </para></entry>
18829 </row>
18831 <row>
18832 <entry role="func_table_entry"><para role="func_signature">
18833 <indexterm id="function-array-to-string">
18834 <primary>array_to_string</primary>
18835 </indexterm>
18836 <function>array_to_string</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>delimiter</parameter> <type>text</type> <optional>, <parameter>null_string</parameter> <type>text</type> </optional> )
18837 <returnvalue>text</returnvalue>
18838 </para>
18839 <para>
18840 Converts each array element to its text representation, and
18841 concatenates those separated by
18842 the <parameter>delimiter</parameter> string.
18843 If <parameter>null_string</parameter> is given and is
18844 not <literal>NULL</literal>, then <literal>NULL</literal> array
18845 entries are represented by that string; otherwise, they are omitted.
18846 See also <link linkend="function-string-to-array"><function>string_to_array</function></link>.
18847 </para>
18848 <para>
18849 <literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal>
18850 <returnvalue>1,2,3,*,5</returnvalue>
18851 </para></entry>
18852 </row>
18854 <row>
18855 <entry role="func_table_entry"><para role="func_signature">
18856 <indexterm>
18857 <primary>array_upper</primary>
18858 </indexterm>
18859 <function>array_upper</function> ( <type>anyarray</type>, <type>integer</type> )
18860 <returnvalue>integer</returnvalue>
18861 </para>
18862 <para>
18863 Returns the upper bound of the requested array dimension.
18864 </para>
18865 <para>
18866 <literal>array_upper(ARRAY[1,8,3,7], 1)</literal>
18867 <returnvalue>4</returnvalue>
18868 </para></entry>
18869 </row>
18871 <row>
18872 <entry role="func_table_entry"><para role="func_signature">
18873 <indexterm>
18874 <primary>cardinality</primary>
18875 </indexterm>
18876 <function>cardinality</function> ( <type>anyarray</type> )
18877 <returnvalue>integer</returnvalue>
18878 </para>
18879 <para>
18880 Returns the total number of elements in the array, or 0 if the array
18881 is empty.
18882 </para>
18883 <para>
18884 <literal>cardinality(ARRAY[[1,2],[3,4]])</literal>
18885 <returnvalue>4</returnvalue>
18886 </para></entry>
18887 </row>
18889 <row>
18890 <entry role="func_table_entry"><para role="func_signature">
18891 <indexterm>
18892 <primary>trim_array</primary>
18893 </indexterm>
18894 <function>trim_array</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
18895 <returnvalue>anyarray</returnvalue>
18896 </para>
18897 <para>
18898 Trims an array by removing the last <parameter>n</parameter> elements.
18899 If the array is multidimensional, only the first dimension is trimmed.
18900 </para>
18901 <para>
18902 <literal>trim_array(ARRAY[1,2,3,4,5,6], 2)</literal>
18903 <returnvalue>{1,2,3,4}</returnvalue>
18904 </para></entry>
18905 </row>
18907 <row>
18908 <entry role="func_table_entry"><para role="func_signature">
18909 <indexterm>
18910 <primary>unnest</primary>
18911 </indexterm>
18912 <function>unnest</function> ( <type>anyarray</type> )
18913 <returnvalue>setof anyelement</returnvalue>
18914 </para>
18915 <para>
18916 Expands an array into a set of rows.
18917 The array's elements are read out in storage order.
18918 </para>
18919 <para>
18920 <literal>unnest(ARRAY[1,2])</literal>
18921 <returnvalue></returnvalue>
18922 <programlisting>
18925 </programlisting>
18926 </para>
18927 <para>
18928 <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])</literal>
18929 <returnvalue></returnvalue>
18930 <programlisting>
18934 quux
18935 </programlisting>
18936 </para></entry>
18937 </row>
18939 <row>
18940 <entry role="func_table_entry"><para role="func_signature">
18941 <function>unnest</function> ( <type>anyarray</type>, <type>anyarray</type> <optional>, ... </optional> )
18942 <returnvalue>setof anyelement, anyelement [, ... ]</returnvalue>
18943 </para>
18944 <para>
18945 Expands multiple arrays (possibly of different data types) into a set of
18946 rows. If the arrays are not all the same length then the shorter ones
18947 are padded with <literal>NULL</literal>s. This form is only allowed
18948 in a query's FROM clause; see <xref linkend="queries-tablefunctions"/>.
18949 </para>
18950 <para>
18951 <literal>select * from unnest(ARRAY[1,2], ARRAY['foo','bar','baz']) as x(a,b)</literal>
18952 <returnvalue></returnvalue>
18953 <programlisting>
18954 a | b
18955 ---+-----
18956 1 | foo
18957 2 | bar
18958 | baz
18959 </programlisting>
18960 </para></entry>
18961 </row>
18962 </tbody>
18963 </tgroup>
18964 </table>
18966 <para>
18967 See also <xref linkend="functions-aggregate"/> about the aggregate
18968 function <function>array_agg</function> for use with arrays.
18969 </para>
18970 </sect1>
18972 <sect1 id="functions-range">
18973 <title>Range/Multirange Functions and Operators</title>
18975 <para>
18976 See <xref linkend="rangetypes"/> for an overview of range types.
18977 </para>
18979 <para>
18980 <xref linkend="range-operators-table"/> shows the specialized operators
18981 available for range types.
18982 <xref linkend="multirange-operators-table"/> shows the specialized operators
18983 available for multirange types.
18984 In addition to those, the usual comparison operators shown in
18985 <xref linkend="functions-comparison-op-table"/> are available for range
18986 and multirange types. The comparison operators order first by the range lower
18987 bounds, and only if those are equal do they compare the upper bounds. The
18988 multirange operators compare each range until one is unequal. This
18989 does not usually result in a useful overall ordering, but the operators are
18990 provided to allow unique indexes to be constructed on ranges.
18991 </para>
18993 <table id="range-operators-table">
18994 <title>Range Operators</title>
18995 <tgroup cols="1">
18996 <thead>
18997 <row>
18998 <entry role="func_table_entry"><para role="func_signature">
18999 Operator
19000 </para>
19001 <para>
19002 Description
19003 </para>
19004 <para>
19005 Example(s)
19006 </para></entry>
19007 </row>
19008 </thead>
19010 <tbody>
19011 <row>
19012 <entry role="func_table_entry"><para role="func_signature">
19013 <type>anyrange</type> <literal>@&gt;</literal> <type>anyrange</type>
19014 <returnvalue>boolean</returnvalue>
19015 </para>
19016 <para>
19017 Does the first range contain the second?
19018 </para>
19019 <para>
19020 <literal>int4range(2,4) @&gt; int4range(2,3)</literal>
19021 <returnvalue>t</returnvalue>
19022 </para></entry>
19023 </row>
19025 <row>
19026 <entry role="func_table_entry"><para role="func_signature">
19027 <type>anyrange</type> <literal>@&gt;</literal> <type>anyelement</type>
19028 <returnvalue>boolean</returnvalue>
19029 </para>
19030 <para>
19031 Does the range contain the element?
19032 </para>
19033 <para>
19034 <literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal>
19035 <returnvalue>t</returnvalue>
19036 </para></entry>
19037 </row>
19039 <row>
19040 <entry role="func_table_entry"><para role="func_signature">
19041 <type>anyrange</type> <literal>&lt;@</literal> <type>anyrange</type>
19042 <returnvalue>boolean</returnvalue>
19043 </para>
19044 <para>
19045 Is the first range contained by the second?
19046 </para>
19047 <para>
19048 <literal>int4range(2,4) &lt;@ int4range(1,7)</literal>
19049 <returnvalue>t</returnvalue>
19050 </para></entry>
19051 </row>
19053 <row>
19054 <entry role="func_table_entry"><para role="func_signature">
19055 <type>anyelement</type> <literal>&lt;@</literal> <type>anyrange</type>
19056 <returnvalue>boolean</returnvalue>
19057 </para>
19058 <para>
19059 Is the element contained in the range?
19060 </para>
19061 <para>
19062 <literal>42 &lt;@ int4range(1,7)</literal>
19063 <returnvalue>f</returnvalue>
19064 </para></entry>
19065 </row>
19067 <row>
19068 <entry role="func_table_entry"><para role="func_signature">
19069 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
19070 <returnvalue>boolean</returnvalue>
19071 </para>
19072 <para>
19073 Do the ranges overlap, that is, have any elements in common?
19074 </para>
19075 <para>
19076 <literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal>
19077 <returnvalue>t</returnvalue>
19078 </para></entry>
19079 </row>
19081 <row>
19082 <entry role="func_table_entry"><para role="func_signature">
19083 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
19084 <returnvalue>boolean</returnvalue>
19085 </para>
19086 <para>
19087 Is the first range strictly left of the second?
19088 </para>
19089 <para>
19090 <literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal>
19091 <returnvalue>t</returnvalue>
19092 </para></entry>
19093 </row>
19095 <row>
19096 <entry role="func_table_entry"><para role="func_signature">
19097 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
19098 <returnvalue>boolean</returnvalue>
19099 </para>
19100 <para>
19101 Is the first range strictly right of the second?
19102 </para>
19103 <para>
19104 <literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal>
19105 <returnvalue>t</returnvalue>
19106 </para></entry>
19107 </row>
19109 <row>
19110 <entry role="func_table_entry"><para role="func_signature">
19111 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
19112 <returnvalue>boolean</returnvalue>
19113 </para>
19114 <para>
19115 Does the first range not extend to the right of the second?
19116 </para>
19117 <para>
19118 <literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal>
19119 <returnvalue>t</returnvalue>
19120 </para></entry>
19121 </row>
19123 <row>
19124 <entry role="func_table_entry"><para role="func_signature">
19125 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
19126 <returnvalue>boolean</returnvalue>
19127 </para>
19128 <para>
19129 Does the first range not extend to the left of the second?
19130 </para>
19131 <para>
19132 <literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal>
19133 <returnvalue>t</returnvalue>
19134 </para></entry>
19135 </row>
19137 <row>
19138 <entry role="func_table_entry"><para role="func_signature">
19139 <type>anyrange</type> <literal>-|-</literal> <type>anyrange</type>
19140 <returnvalue>boolean</returnvalue>
19141 </para>
19142 <para>
19143 Are the ranges adjacent?
19144 </para>
19145 <para>
19146 <literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal>
19147 <returnvalue>t</returnvalue>
19148 </para></entry>
19149 </row>
19151 <row>
19152 <entry role="func_table_entry"><para role="func_signature">
19153 <type>anyrange</type> <literal>+</literal> <type>anyrange</type>
19154 <returnvalue>anyrange</returnvalue>
19155 </para>
19156 <para>
19157 Computes the union of the ranges. The ranges must overlap or be
19158 adjacent, so that the union is a single range (but
19159 see <function>range_merge()</function>).
19160 </para>
19161 <para>
19162 <literal>numrange(5,15) + numrange(10,20)</literal>
19163 <returnvalue>[5,20)</returnvalue>
19164 </para></entry>
19165 </row>
19167 <row>
19168 <entry role="func_table_entry"><para role="func_signature">
19169 <type>anyrange</type> <literal>*</literal> <type>anyrange</type>
19170 <returnvalue>anyrange</returnvalue>
19171 </para>
19172 <para>
19173 Computes the intersection of the ranges.
19174 </para>
19175 <para>
19176 <literal>int8range(5,15) * int8range(10,20)</literal>
19177 <returnvalue>[10,15)</returnvalue>
19178 </para></entry>
19179 </row>
19181 <row>
19182 <entry role="func_table_entry"><para role="func_signature">
19183 <type>anyrange</type> <literal>-</literal> <type>anyrange</type>
19184 <returnvalue>anyrange</returnvalue>
19185 </para>
19186 <para>
19187 Computes the difference of the ranges. The second range must not be
19188 contained in the first in such a way that the difference would not be
19189 a single range.
19190 </para>
19191 <para>
19192 <literal>int8range(5,15) - int8range(10,20)</literal>
19193 <returnvalue>[5,10)</returnvalue>
19194 </para></entry>
19195 </row>
19196 </tbody>
19197 </tgroup>
19198 </table>
19200 <table id="multirange-operators-table">
19201 <title>Multirange Operators</title>
19202 <tgroup cols="1">
19203 <thead>
19204 <row>
19205 <entry role="func_table_entry"><para role="func_signature">
19206 Operator
19207 </para>
19208 <para>
19209 Description
19210 </para>
19211 <para>
19212 Example(s)
19213 </para></entry>
19214 </row>
19215 </thead>
19217 <tbody>
19218 <row>
19219 <entry role="func_table_entry"><para role="func_signature">
19220 <type>anymultirange</type> <literal>@&gt;</literal> <type>anymultirange</type>
19221 <returnvalue>boolean</returnvalue>
19222 </para>
19223 <para>
19224 Does the first multirange contain the second?
19225 </para>
19226 <para>
19227 <literal>'{[2,4)}'::int4multirange @&gt; '{[2,3)}'::int4multirange</literal>
19228 <returnvalue>t</returnvalue>
19229 </para></entry>
19230 </row>
19232 <row>
19233 <entry role="func_table_entry"><para role="func_signature">
19234 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyrange</type>
19235 <returnvalue>boolean</returnvalue>
19236 </para>
19237 <para>
19238 Does the multirange contain the range?
19239 </para>
19240 <para>
19241 <literal>'{[2,4)}'::int4multirange @&gt; int4range(2,3)</literal>
19242 <returnvalue>t</returnvalue>
19243 </para></entry>
19244 </row>
19246 <row>
19247 <entry role="func_table_entry"><para role="func_signature">
19248 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyelement</type>
19249 <returnvalue>boolean</returnvalue>
19250 </para>
19251 <para>
19252 Does the multirange contain the element?
19253 </para>
19254 <para>
19255 <literal>'{[2011-01-01,2011-03-01)}'::tsmultirange @&gt; '2011-01-10'::timestamp</literal>
19256 <returnvalue>t</returnvalue>
19257 </para></entry>
19258 </row>
19260 <row>
19261 <entry role="func_table_entry"><para role="func_signature">
19262 <type>anyrange</type> <literal>@&gt;</literal> <type>anymultirange</type>
19263 <returnvalue>boolean</returnvalue>
19264 </para>
19265 <para>
19266 Does the range contain the multirange?
19267 </para>
19268 <para>
19269 <literal>'[2,4)'::int4range @&gt; '{[2,3)}'::int4multirange</literal>
19270 <returnvalue>t</returnvalue>
19271 </para></entry>
19272 </row>
19274 <row>
19275 <entry role="func_table_entry"><para role="func_signature">
19276 <type>anymultirange</type> <literal>&lt;@</literal> <type>anymultirange</type>
19277 <returnvalue>boolean</returnvalue>
19278 </para>
19279 <para>
19280 Is the first multirange contained by the second?
19281 </para>
19282 <para>
19283 <literal>'{[2,4)}'::int4multirange &lt;@ '{[1,7)}'::int4multirange</literal>
19284 <returnvalue>t</returnvalue>
19285 </para></entry>
19286 </row>
19288 <row>
19289 <entry role="func_table_entry"><para role="func_signature">
19290 <type>anymultirange</type> <literal>&lt;@</literal> <type>anyrange</type>
19291 <returnvalue>boolean</returnvalue>
19292 </para>
19293 <para>
19294 Is the multirange contained by the range?
19295 </para>
19296 <para>
19297 <literal>'{[2,4)}'::int4multirange &lt;@ int4range(1,7)</literal>
19298 <returnvalue>t</returnvalue>
19299 </para></entry>
19300 </row>
19302 <row>
19303 <entry role="func_table_entry"><para role="func_signature">
19304 <type>anyrange</type> <literal>&lt;@</literal> <type>anymultirange</type>
19305 <returnvalue>boolean</returnvalue>
19306 </para>
19307 <para>
19308 Is the range contained by the multirange?
19309 </para>
19310 <para>
19311 <literal>int4range(2,4) &lt;@ '{[1,7)}'::int4multirange</literal>
19312 <returnvalue>t</returnvalue>
19313 </para></entry>
19314 </row>
19316 <row>
19317 <entry role="func_table_entry"><para role="func_signature">
19318 <type>anyelement</type> <literal>&lt;@</literal> <type>anymultirange</type>
19319 <returnvalue>boolean</returnvalue>
19320 </para>
19321 <para>
19322 Is the element contained by the multirange?
19323 </para>
19324 <para>
19325 <literal>4 &lt;@ '{[1,7)}'::int4multirange</literal>
19326 <returnvalue>t</returnvalue>
19327 </para></entry>
19328 </row>
19330 <row>
19331 <entry role="func_table_entry"><para role="func_signature">
19332 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
19333 <returnvalue>boolean</returnvalue>
19334 </para>
19335 <para>
19336 Do the multiranges overlap, that is, have any elements in common?
19337 </para>
19338 <para>
19339 <literal>'{[3,7)}'::int8multirange &amp;&amp; '{[4,12)}'::int8multirange</literal>
19340 <returnvalue>t</returnvalue>
19341 </para></entry>
19342 </row>
19344 <row>
19345 <entry role="func_table_entry"><para role="func_signature">
19346 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
19347 <returnvalue>boolean</returnvalue>
19348 </para>
19349 <para>
19350 Does the multirange overlap the range?
19351 </para>
19352 <para>
19353 <literal>'{[3,7)}'::int8multirange &amp;&amp; int8range(4,12)</literal>
19354 <returnvalue>t</returnvalue>
19355 </para></entry>
19356 </row>
19358 <row>
19359 <entry role="func_table_entry"><para role="func_signature">
19360 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
19361 <returnvalue>boolean</returnvalue>
19362 </para>
19363 <para>
19364 Does the range overlap the multirange?
19365 </para>
19366 <para>
19367 <literal>int8range(3,7) &amp;&amp; '{[4,12)}'::int8multirange</literal>
19368 <returnvalue>t</returnvalue>
19369 </para></entry>
19370 </row>
19372 <row>
19373 <entry role="func_table_entry"><para role="func_signature">
19374 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
19375 <returnvalue>boolean</returnvalue>
19376 </para>
19377 <para>
19378 Is the first multirange strictly left of the second?
19379 </para>
19380 <para>
19381 <literal>'{[1,10)}'::int8multirange &lt;&lt; '{[100,110)}'::int8multirange</literal>
19382 <returnvalue>t</returnvalue>
19383 </para></entry>
19384 </row>
19386 <row>
19387 <entry role="func_table_entry"><para role="func_signature">
19388 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
19389 <returnvalue>boolean</returnvalue>
19390 </para>
19391 <para>
19392 Is the multirange strictly left of the range?
19393 </para>
19394 <para>
19395 <literal>'{[1,10)}'::int8multirange &lt;&lt; int8range(100,110)</literal>
19396 <returnvalue>t</returnvalue>
19397 </para></entry>
19398 </row>
19400 <row>
19401 <entry role="func_table_entry"><para role="func_signature">
19402 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
19403 <returnvalue>boolean</returnvalue>
19404 </para>
19405 <para>
19406 Is the range strictly left of the multirange?
19407 </para>
19408 <para>
19409 <literal>int8range(1,10) &lt;&lt; '{[100,110)}'::int8multirange</literal>
19410 <returnvalue>t</returnvalue>
19411 </para></entry>
19412 </row>
19414 <row>
19415 <entry role="func_table_entry"><para role="func_signature">
19416 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
19417 <returnvalue>boolean</returnvalue>
19418 </para>
19419 <para>
19420 Is the first multirange strictly right of the second?
19421 </para>
19422 <para>
19423 <literal>'{[50,60)}'::int8multirange &gt;&gt; '{[20,30)}'::int8multirange</literal>
19424 <returnvalue>t</returnvalue>
19425 </para></entry>
19426 </row>
19428 <row>
19429 <entry role="func_table_entry"><para role="func_signature">
19430 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
19431 <returnvalue>boolean</returnvalue>
19432 </para>
19433 <para>
19434 Is the multirange strictly right of the range?
19435 </para>
19436 <para>
19437 <literal>'{[50,60)}'::int8multirange &gt;&gt; int8range(20,30)</literal>
19438 <returnvalue>t</returnvalue>
19439 </para></entry>
19440 </row>
19442 <row>
19443 <entry role="func_table_entry"><para role="func_signature">
19444 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
19445 <returnvalue>boolean</returnvalue>
19446 </para>
19447 <para>
19448 Is the range strictly right of the multirange?
19449 </para>
19450 <para>
19451 <literal>int8range(50,60) &gt;&gt; '{[20,30)}'::int8multirange</literal>
19452 <returnvalue>t</returnvalue>
19453 </para></entry>
19454 </row>
19456 <row>
19457 <entry role="func_table_entry"><para role="func_signature">
19458 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
19459 <returnvalue>boolean</returnvalue>
19460 </para>
19461 <para>
19462 Does the first multirange not extend to the right of the second?
19463 </para>
19464 <para>
19465 <literal>'{[1,20)}'::int8multirange &amp;&lt; '{[18,20)}'::int8multirange</literal>
19466 <returnvalue>t</returnvalue>
19467 </para></entry>
19468 </row>
19470 <row>
19471 <entry role="func_table_entry"><para role="func_signature">
19472 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
19473 <returnvalue>boolean</returnvalue>
19474 </para>
19475 <para>
19476 Does the multirange not extend to the right of the range?
19477 </para>
19478 <para>
19479 <literal>'{[1,20)}'::int8multirange &amp;&lt; int8range(18,20)</literal>
19480 <returnvalue>t</returnvalue>
19481 </para></entry>
19482 </row>
19484 <row>
19485 <entry role="func_table_entry"><para role="func_signature">
19486 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
19487 <returnvalue>boolean</returnvalue>
19488 </para>
19489 <para>
19490 Does the range not extend to the right of the multirange?
19491 </para>
19492 <para>
19493 <literal>int8range(1,20) &amp;&lt; '{[18,20)}'::int8multirange</literal>
19494 <returnvalue>t</returnvalue>
19495 </para></entry>
19496 </row>
19498 <row>
19499 <entry role="func_table_entry"><para role="func_signature">
19500 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
19501 <returnvalue>boolean</returnvalue>
19502 </para>
19503 <para>
19504 Does the first multirange not extend to the left of the second?
19505 </para>
19506 <para>
19507 <literal>'{[7,20)}'::int8multirange &amp;&gt; '{[5,10)}'::int8multirange</literal>
19508 <returnvalue>t</returnvalue>
19509 </para></entry>
19510 </row>
19512 <row>
19513 <entry role="func_table_entry"><para role="func_signature">
19514 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
19515 <returnvalue>boolean</returnvalue>
19516 </para>
19517 <para>
19518 Does the multirange not extend to the left of the range?
19519 </para>
19520 <para>
19521 <literal>'{[7,20)}'::int8multirange &amp;&gt; int8range(5,10)</literal>
19522 <returnvalue>t</returnvalue>
19523 </para></entry>
19524 </row>
19526 <row>
19527 <entry role="func_table_entry"><para role="func_signature">
19528 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
19529 <returnvalue>boolean</returnvalue>
19530 </para>
19531 <para>
19532 Does the range not extend to the left of the multirange?
19533 </para>
19534 <para>
19535 <literal>int8range(7,20) &amp;&gt; '{[5,10)}'::int8multirange</literal>
19536 <returnvalue>t</returnvalue>
19537 </para></entry>
19538 </row>
19540 <row>
19541 <entry role="func_table_entry"><para role="func_signature">
19542 <type>anymultirange</type> <literal>-|-</literal> <type>anymultirange</type>
19543 <returnvalue>boolean</returnvalue>
19544 </para>
19545 <para>
19546 Are the multiranges adjacent?
19547 </para>
19548 <para>
19549 <literal>'{[1.1,2.2)}'::nummultirange -|- '{[2.2,3.3)}'::nummultirange</literal>
19550 <returnvalue>t</returnvalue>
19551 </para></entry>
19552 </row>
19554 <row>
19555 <entry role="func_table_entry"><para role="func_signature">
19556 <type>anymultirange</type> <literal>-|-</literal> <type>anyrange</type>
19557 <returnvalue>boolean</returnvalue>
19558 </para>
19559 <para>
19560 Is the multirange adjacent to the range?
19561 </para>
19562 <para>
19563 <literal>'{[1.1,2.2)}'::nummultirange -|- numrange(2.2,3.3)</literal>
19564 <returnvalue>t</returnvalue>
19565 </para></entry>
19566 </row>
19568 <row>
19569 <entry role="func_table_entry"><para role="func_signature">
19570 <type>anyrange</type> <literal>-|-</literal> <type>anymultirange</type>
19571 <returnvalue>boolean</returnvalue>
19572 </para>
19573 <para>
19574 Is the range adjacent to the multirange?
19575 </para>
19576 <para>
19577 <literal>numrange(1.1,2.2) -|- '{[2.2,3.3)}'::nummultirange</literal>
19578 <returnvalue>t</returnvalue>
19579 </para></entry>
19580 </row>
19582 <row>
19583 <entry role="func_table_entry"><para role="func_signature">
19584 <type>anymultirange</type> <literal>+</literal> <type>anymultirange</type>
19585 <returnvalue>anymultirange</returnvalue>
19586 </para>
19587 <para>
19588 Computes the union of the multiranges. The multiranges need not overlap
19589 or be adjacent.
19590 </para>
19591 <para>
19592 <literal>'{[5,10)}'::nummultirange + '{[15,20)}'::nummultirange</literal>
19593 <returnvalue>{[5,10), [15,20)}</returnvalue>
19594 </para></entry>
19595 </row>
19597 <row>
19598 <entry role="func_table_entry"><para role="func_signature">
19599 <type>anymultirange</type> <literal>*</literal> <type>anymultirange</type>
19600 <returnvalue>anymultirange</returnvalue>
19601 </para>
19602 <para>
19603 Computes the intersection of the multiranges.
19604 </para>
19605 <para>
19606 <literal>'{[5,15)}'::int8multirange * '{[10,20)}'::int8multirange</literal>
19607 <returnvalue>{[10,15)}</returnvalue>
19608 </para></entry>
19609 </row>
19611 <row>
19612 <entry role="func_table_entry"><para role="func_signature">
19613 <type>anymultirange</type> <literal>-</literal> <type>anymultirange</type>
19614 <returnvalue>anymultirange</returnvalue>
19615 </para>
19616 <para>
19617 Computes the difference of the multiranges.
19618 </para>
19619 <para>
19620 <literal>'{[5,20)}'::int8multirange - '{[10,15)}'::int8multirange</literal>
19621 <returnvalue>{[5,10), [15,20)}</returnvalue>
19622 </para></entry>
19623 </row>
19624 </tbody>
19625 </tgroup>
19626 </table>
19628 <para>
19629 The left-of/right-of/adjacent operators always return false when an empty
19630 range or multirange is involved; that is, an empty range is not considered to
19631 be either before or after any other range.
19632 </para>
19634 <para>
19635 Elsewhere empty ranges and multiranges are treated as the additive identity:
19636 anything unioned with an empty value is itself. Anything minus an empty
19637 value is itself. An empty multirange has exactly the same points as an empty
19638 range. Every range contains the empty range. Every multirange contains as many
19639 empty ranges as you like.
19640 </para>
19642 <para>
19643 The range union and difference operators will fail if the resulting range would
19644 need to contain two disjoint sub-ranges, as such a range cannot be
19645 represented. There are separate operators for union and difference that take
19646 multirange parameters and return a multirange, and they do not fail even if
19647 their arguments are disjoint. So if you need a union or difference operation
19648 for ranges that may be disjoint, you can avoid errors by first casting your
19649 ranges to multiranges.
19650 </para>
19652 <para>
19653 <xref linkend="range-functions-table"/> shows the functions
19654 available for use with range types.
19655 <xref linkend="multirange-functions-table"/> shows the functions
19656 available for use with multirange types.
19657 </para>
19659 <table id="range-functions-table">
19660 <title>Range Functions</title>
19661 <tgroup cols="1">
19662 <thead>
19663 <row>
19664 <entry role="func_table_entry"><para role="func_signature">
19665 Function
19666 </para>
19667 <para>
19668 Description
19669 </para>
19670 <para>
19671 Example(s)
19672 </para></entry>
19673 </row>
19674 </thead>
19676 <tbody>
19677 <row>
19678 <entry role="func_table_entry"><para role="func_signature">
19679 <indexterm>
19680 <primary>lower</primary>
19681 </indexterm>
19682 <function>lower</function> ( <type>anyrange</type> )
19683 <returnvalue>anyelement</returnvalue>
19684 </para>
19685 <para>
19686 Extracts the lower bound of the range (<literal>NULL</literal> if the
19687 range is empty or has no lower bound).
19688 </para>
19689 <para>
19690 <literal>lower(numrange(1.1,2.2))</literal>
19691 <returnvalue>1.1</returnvalue>
19692 </para></entry>
19693 </row>
19695 <row>
19696 <entry role="func_table_entry"><para role="func_signature">
19697 <indexterm>
19698 <primary>upper</primary>
19699 </indexterm>
19700 <function>upper</function> ( <type>anyrange</type> )
19701 <returnvalue>anyelement</returnvalue>
19702 </para>
19703 <para>
19704 Extracts the upper bound of the range (<literal>NULL</literal> if the
19705 range is empty or has no upper bound).
19706 </para>
19707 <para>
19708 <literal>upper(numrange(1.1,2.2))</literal>
19709 <returnvalue>2.2</returnvalue>
19710 </para></entry>
19711 </row>
19713 <row>
19714 <entry role="func_table_entry"><para role="func_signature">
19715 <indexterm>
19716 <primary>isempty</primary>
19717 </indexterm>
19718 <function>isempty</function> ( <type>anyrange</type> )
19719 <returnvalue>boolean</returnvalue>
19720 </para>
19721 <para>
19722 Is the range empty?
19723 </para>
19724 <para>
19725 <literal>isempty(numrange(1.1,2.2))</literal>
19726 <returnvalue>f</returnvalue>
19727 </para></entry>
19728 </row>
19730 <row>
19731 <entry role="func_table_entry"><para role="func_signature">
19732 <indexterm>
19733 <primary>lower_inc</primary>
19734 </indexterm>
19735 <function>lower_inc</function> ( <type>anyrange</type> )
19736 <returnvalue>boolean</returnvalue>
19737 </para>
19738 <para>
19739 Is the range's lower bound inclusive?
19740 </para>
19741 <para>
19742 <literal>lower_inc(numrange(1.1,2.2))</literal>
19743 <returnvalue>t</returnvalue>
19744 </para></entry>
19745 </row>
19747 <row>
19748 <entry role="func_table_entry"><para role="func_signature">
19749 <indexterm>
19750 <primary>upper_inc</primary>
19751 </indexterm>
19752 <function>upper_inc</function> ( <type>anyrange</type> )
19753 <returnvalue>boolean</returnvalue>
19754 </para>
19755 <para>
19756 Is the range's upper bound inclusive?
19757 </para>
19758 <para>
19759 <literal>upper_inc(numrange(1.1,2.2))</literal>
19760 <returnvalue>f</returnvalue>
19761 </para></entry>
19762 </row>
19764 <row>
19765 <entry role="func_table_entry"><para role="func_signature">
19766 <indexterm>
19767 <primary>lower_inf</primary>
19768 </indexterm>
19769 <function>lower_inf</function> ( <type>anyrange</type> )
19770 <returnvalue>boolean</returnvalue>
19771 </para>
19772 <para>
19773 Does the range have no lower bound? (A lower bound of
19774 <literal>-Infinity</literal> returns false.)
19775 </para>
19776 <para>
19777 <literal>lower_inf('(,)'::daterange)</literal>
19778 <returnvalue>t</returnvalue>
19779 </para></entry>
19780 </row>
19782 <row>
19783 <entry role="func_table_entry"><para role="func_signature">
19784 <indexterm>
19785 <primary>upper_inf</primary>
19786 </indexterm>
19787 <function>upper_inf</function> ( <type>anyrange</type> )
19788 <returnvalue>boolean</returnvalue>
19789 </para>
19790 <para>
19791 Does the range have no upper bound? (An upper bound of
19792 <literal>Infinity</literal> returns false.)
19793 </para>
19794 <para>
19795 <literal>upper_inf('(,)'::daterange)</literal>
19796 <returnvalue>t</returnvalue>
19797 </para></entry>
19798 </row>
19800 <row>
19801 <entry role="func_table_entry"><para role="func_signature">
19802 <indexterm>
19803 <primary>range_merge</primary>
19804 </indexterm>
19805 <function>range_merge</function> ( <type>anyrange</type>, <type>anyrange</type> )
19806 <returnvalue>anyrange</returnvalue>
19807 </para>
19808 <para>
19809 Computes the smallest range that includes both of the given ranges.
19810 </para>
19811 <para>
19812 <literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal>
19813 <returnvalue>[1,4)</returnvalue>
19814 </para></entry>
19815 </row>
19816 </tbody>
19817 </tgroup>
19818 </table>
19820 <table id="multirange-functions-table">
19821 <title>Multirange Functions</title>
19822 <tgroup cols="1">
19823 <thead>
19824 <row>
19825 <entry role="func_table_entry"><para role="func_signature">
19826 Function
19827 </para>
19828 <para>
19829 Description
19830 </para>
19831 <para>
19832 Example(s)
19833 </para></entry>
19834 </row>
19835 </thead>
19836 <tbody>
19837 <row>
19838 <entry role="func_table_entry"><para role="func_signature">
19839 <indexterm>
19840 <primary>lower</primary>
19841 </indexterm>
19842 <function>lower</function> ( <type>anymultirange</type> )
19843 <returnvalue>anyelement</returnvalue>
19844 </para>
19845 <para>
19846 Extracts the lower bound of the multirange (<literal>NULL</literal> if the
19847 multirange is empty has no lower bound).
19848 </para>
19849 <para>
19850 <literal>lower('{[1.1,2.2)}'::nummultirange)</literal>
19851 <returnvalue>1.1</returnvalue>
19852 </para></entry>
19853 </row>
19855 <row>
19856 <entry role="func_table_entry"><para role="func_signature">
19857 <indexterm>
19858 <primary>upper</primary>
19859 </indexterm>
19860 <function>upper</function> ( <type>anymultirange</type> )
19861 <returnvalue>anyelement</returnvalue>
19862 </para>
19863 <para>
19864 Extracts the upper bound of the multirange (<literal>NULL</literal> if the
19865 multirange is empty or has no upper bound).
19866 </para>
19867 <para>
19868 <literal>upper('{[1.1,2.2)}'::nummultirange)</literal>
19869 <returnvalue>2.2</returnvalue>
19870 </para></entry>
19871 </row>
19873 <row>
19874 <entry role="func_table_entry"><para role="func_signature">
19875 <indexterm>
19876 <primary>isempty</primary>
19877 </indexterm>
19878 <function>isempty</function> ( <type>anymultirange</type> )
19879 <returnvalue>boolean</returnvalue>
19880 </para>
19881 <para>
19882 Is the multirange empty?
19883 </para>
19884 <para>
19885 <literal>isempty('{[1.1,2.2)}'::nummultirange)</literal>
19886 <returnvalue>f</returnvalue>
19887 </para></entry>
19888 </row>
19890 <row>
19891 <entry role="func_table_entry"><para role="func_signature">
19892 <indexterm>
19893 <primary>lower_inc</primary>
19894 </indexterm>
19895 <function>lower_inc</function> ( <type>anymultirange</type> )
19896 <returnvalue>boolean</returnvalue>
19897 </para>
19898 <para>
19899 Is the multirange's lower bound inclusive?
19900 </para>
19901 <para>
19902 <literal>lower_inc('{[1.1,2.2)}'::nummultirange)</literal>
19903 <returnvalue>t</returnvalue>
19904 </para></entry>
19905 </row>
19907 <row>
19908 <entry role="func_table_entry"><para role="func_signature">
19909 <indexterm>
19910 <primary>upper_inc</primary>
19911 </indexterm>
19912 <function>upper_inc</function> ( <type>anymultirange</type> )
19913 <returnvalue>boolean</returnvalue>
19914 </para>
19915 <para>
19916 Is the multirange's upper bound inclusive?
19917 </para>
19918 <para>
19919 <literal>upper_inc('{[1.1,2.2)}'::nummultirange)</literal>
19920 <returnvalue>f</returnvalue>
19921 </para></entry>
19922 </row>
19924 <row>
19925 <entry role="func_table_entry"><para role="func_signature">
19926 <indexterm>
19927 <primary>lower_inf</primary>
19928 </indexterm>
19929 <function>lower_inf</function> ( <type>anymultirange</type> )
19930 <returnvalue>boolean</returnvalue>
19931 </para>
19932 <para>
19933 Does the multirange have no lower bound? (A lower bound of
19934 <literal>-Infinity</literal> returns false.)
19935 </para>
19936 <para>
19937 <literal>lower_inf('{(,)}'::datemultirange)</literal>
19938 <returnvalue>t</returnvalue>
19939 </para></entry>
19940 </row>
19942 <row>
19943 <entry role="func_table_entry"><para role="func_signature">
19944 <indexterm>
19945 <primary>upper_inf</primary>
19946 </indexterm>
19947 <function>upper_inf</function> ( <type>anymultirange</type> )
19948 <returnvalue>boolean</returnvalue>
19949 </para>
19950 <para>
19951 Does the multirange have no upper bound? (An upper bound of
19952 <literal>Infinity</literal> returns false.)
19953 </para>
19954 <para>
19955 <literal>upper_inf('{(,)}'::datemultirange)</literal>
19956 <returnvalue>t</returnvalue>
19957 </para></entry>
19958 </row>
19960 <row>
19961 <entry role="func_table_entry"><para role="func_signature">
19962 <indexterm>
19963 <primary>range_merge</primary>
19964 </indexterm>
19965 <function>range_merge</function> ( <type>anymultirange</type> )
19966 <returnvalue>anyrange</returnvalue>
19967 </para>
19968 <para>
19969 Computes the smallest range that includes the entire multirange.
19970 </para>
19971 <para>
19972 <literal>range_merge('{[1,2), [3,4)}'::int4multirange)</literal>
19973 <returnvalue>[1,4)</returnvalue>
19974 </para></entry>
19975 </row>
19977 <row>
19978 <entry role="func_table_entry"><para role="func_signature">
19979 <indexterm>
19980 <primary>multirange (function)</primary>
19981 </indexterm>
19982 <function>multirange</function> ( <type>anyrange</type> )
19983 <returnvalue>anymultirange</returnvalue>
19984 </para>
19985 <para>
19986 Returns a multirange containing just the given range.
19987 </para>
19988 <para>
19989 <literal>multirange('[1,2)'::int4range)</literal>
19990 <returnvalue>{[1,2)}</returnvalue>
19991 </para></entry>
19992 </row>
19994 <row>
19995 <entry role="func_table_entry"><para role="func_signature">
19996 <indexterm>
19997 <primary>unnest</primary>
19998 <secondary>for multirange</secondary>
19999 </indexterm>
20000 <function>unnest</function> ( <type>anymultirange</type> )
20001 <returnvalue>setof anyrange</returnvalue>
20002 </para>
20003 <para>
20004 Expands a multirange into a set of ranges.
20005 The ranges are read out in storage order (ascending).
20006 </para>
20007 <para>
20008 <literal>unnest('{[1,2), [3,4)}'::int4multirange)</literal>
20009 <returnvalue></returnvalue>
20010 <programlisting>
20011 [1,2)
20012 [3,4)
20013 </programlisting>
20014 </para></entry>
20015 </row>
20016 </tbody>
20017 </tgroup>
20018 </table>
20020 <para>
20021 The <function>lower_inc</function>, <function>upper_inc</function>,
20022 <function>lower_inf</function>, and <function>upper_inf</function>
20023 functions all return false for an empty range or multirange.
20024 </para>
20025 </sect1>
20027 <sect1 id="functions-aggregate">
20028 <title>Aggregate Functions</title>
20030 <indexterm zone="functions-aggregate">
20031 <primary>aggregate function</primary>
20032 <secondary>built-in</secondary>
20033 </indexterm>
20035 <para>
20036 <firstterm>Aggregate functions</firstterm> compute a single result
20037 from a set of input values. The built-in general-purpose aggregate
20038 functions are listed in <xref linkend="functions-aggregate-table"/>
20039 while statistical aggregates are in <xref
20040 linkend="functions-aggregate-statistics-table"/>.
20041 The built-in within-group ordered-set aggregate functions
20042 are listed in <xref linkend="functions-orderedset-table"/>
20043 while the built-in within-group hypothetical-set ones are in <xref
20044 linkend="functions-hypothetical-table"/>. Grouping operations,
20045 which are closely related to aggregate functions, are listed in
20046 <xref linkend="functions-grouping-table"/>.
20047 The special syntax considerations for aggregate
20048 functions are explained in <xref linkend="syntax-aggregates"/>.
20049 Consult <xref linkend="tutorial-agg"/> for additional introductory
20050 information.
20051 </para>
20053 <para>
20054 Aggregate functions that support <firstterm>Partial Mode</firstterm>
20055 are eligible to participate in various optimizations, such as parallel
20056 aggregation.
20057 </para>
20059 <table id="functions-aggregate-table">
20060 <title>General-Purpose Aggregate Functions</title>
20061 <tgroup cols="2">
20062 <colspec colname="col1" colwidth="10*"/>
20063 <colspec colname="col2" colwidth="1*"/>
20064 <thead>
20065 <row>
20066 <entry role="func_table_entry"><para role="func_signature">
20067 Function
20068 </para>
20069 <para>
20070 Description
20071 </para></entry>
20072 <entry>Partial Mode</entry>
20073 </row>
20074 </thead>
20076 <tbody>
20077 <row>
20078 <entry role="func_table_entry"><para role="func_signature">
20079 <indexterm>
20080 <primary>any_value</primary>
20081 </indexterm>
20082 <function>any_value</function> ( <type>anyelement</type> )
20083 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
20084 </para>
20085 <para>
20086 Returns an arbitrary value from the non-null input values.
20087 </para></entry>
20088 <entry>Yes</entry>
20089 </row>
20091 <row>
20092 <entry role="func_table_entry"><para role="func_signature">
20093 <indexterm>
20094 <primary>array_agg</primary>
20095 </indexterm>
20096 <function>array_agg</function> ( <type>anynonarray</type> )
20097 <returnvalue>anyarray</returnvalue>
20098 </para>
20099 <para>
20100 Collects all the input values, including nulls, into an array.
20101 </para></entry>
20102 <entry>Yes</entry>
20103 </row>
20105 <row>
20106 <entry role="func_table_entry"><para role="func_signature">
20107 <function>array_agg</function> ( <type>anyarray</type> )
20108 <returnvalue>anyarray</returnvalue>
20109 </para>
20110 <para>
20111 Concatenates all the input arrays into an array of one higher
20112 dimension. (The inputs must all have the same dimensionality, and
20113 cannot be empty or null.)
20114 </para></entry>
20115 <entry>Yes</entry>
20116 </row>
20118 <row>
20119 <entry role="func_table_entry"><para role="func_signature">
20120 <indexterm>
20121 <primary>average</primary>
20122 </indexterm>
20123 <indexterm>
20124 <primary>avg</primary>
20125 </indexterm>
20126 <function>avg</function> ( <type>smallint</type> )
20127 <returnvalue>numeric</returnvalue>
20128 </para>
20129 <para role="func_signature">
20130 <function>avg</function> ( <type>integer</type> )
20131 <returnvalue>numeric</returnvalue>
20132 </para>
20133 <para role="func_signature">
20134 <function>avg</function> ( <type>bigint</type> )
20135 <returnvalue>numeric</returnvalue>
20136 </para>
20137 <para role="func_signature">
20138 <function>avg</function> ( <type>numeric</type> )
20139 <returnvalue>numeric</returnvalue>
20140 </para>
20141 <para role="func_signature">
20142 <function>avg</function> ( <type>real</type> )
20143 <returnvalue>double precision</returnvalue>
20144 </para>
20145 <para role="func_signature">
20146 <function>avg</function> ( <type>double precision</type> )
20147 <returnvalue>double precision</returnvalue>
20148 </para>
20149 <para role="func_signature">
20150 <function>avg</function> ( <type>interval</type> )
20151 <returnvalue>interval</returnvalue>
20152 </para>
20153 <para>
20154 Computes the average (arithmetic mean) of all the non-null input
20155 values.
20156 </para></entry>
20157 <entry>Yes</entry>
20158 </row>
20160 <row>
20161 <entry role="func_table_entry"><para role="func_signature">
20162 <indexterm>
20163 <primary>bit_and</primary>
20164 </indexterm>
20165 <function>bit_and</function> ( <type>smallint</type> )
20166 <returnvalue>smallint</returnvalue>
20167 </para>
20168 <para role="func_signature">
20169 <function>bit_and</function> ( <type>integer</type> )
20170 <returnvalue>integer</returnvalue>
20171 </para>
20172 <para role="func_signature">
20173 <function>bit_and</function> ( <type>bigint</type> )
20174 <returnvalue>bigint</returnvalue>
20175 </para>
20176 <para role="func_signature">
20177 <function>bit_and</function> ( <type>bit</type> )
20178 <returnvalue>bit</returnvalue>
20179 </para>
20180 <para>
20181 Computes the bitwise AND of all non-null input values.
20182 </para></entry>
20183 <entry>Yes</entry>
20184 </row>
20186 <row>
20187 <entry role="func_table_entry"><para role="func_signature">
20188 <indexterm>
20189 <primary>bit_or</primary>
20190 </indexterm>
20191 <function>bit_or</function> ( <type>smallint</type> )
20192 <returnvalue>smallint</returnvalue>
20193 </para>
20194 <para role="func_signature">
20195 <function>bit_or</function> ( <type>integer</type> )
20196 <returnvalue>integer</returnvalue>
20197 </para>
20198 <para role="func_signature">
20199 <function>bit_or</function> ( <type>bigint</type> )
20200 <returnvalue>bigint</returnvalue>
20201 </para>
20202 <para role="func_signature">
20203 <function>bit_or</function> ( <type>bit</type> )
20204 <returnvalue>bit</returnvalue>
20205 </para>
20206 <para>
20207 Computes the bitwise OR of all non-null input values.
20208 </para></entry>
20209 <entry>Yes</entry>
20210 </row>
20212 <row>
20213 <entry role="func_table_entry"><para role="func_signature">
20214 <indexterm>
20215 <primary>bit_xor</primary>
20216 </indexterm>
20217 <function>bit_xor</function> ( <type>smallint</type> )
20218 <returnvalue>smallint</returnvalue>
20219 </para>
20220 <para role="func_signature">
20221 <function>bit_xor</function> ( <type>integer</type> )
20222 <returnvalue>integer</returnvalue>
20223 </para>
20224 <para role="func_signature">
20225 <function>bit_xor</function> ( <type>bigint</type> )
20226 <returnvalue>bigint</returnvalue>
20227 </para>
20228 <para role="func_signature">
20229 <function>bit_xor</function> ( <type>bit</type> )
20230 <returnvalue>bit</returnvalue>
20231 </para>
20232 <para>
20233 Computes the bitwise exclusive OR of all non-null input values.
20234 Can be useful as a checksum for an unordered set of values.
20235 </para></entry>
20236 <entry>Yes</entry>
20237 </row>
20239 <row>
20240 <entry role="func_table_entry"><para role="func_signature">
20241 <indexterm>
20242 <primary>bool_and</primary>
20243 </indexterm>
20244 <function>bool_and</function> ( <type>boolean</type> )
20245 <returnvalue>boolean</returnvalue>
20246 </para>
20247 <para>
20248 Returns true if all non-null input values are true, otherwise false.
20249 </para></entry>
20250 <entry>Yes</entry>
20251 </row>
20253 <row>
20254 <entry role="func_table_entry"><para role="func_signature">
20255 <indexterm>
20256 <primary>bool_or</primary>
20257 </indexterm>
20258 <function>bool_or</function> ( <type>boolean</type> )
20259 <returnvalue>boolean</returnvalue>
20260 </para>
20261 <para>
20262 Returns true if any non-null input value is true, otherwise false.
20263 </para></entry>
20264 <entry>Yes</entry>
20265 </row>
20267 <row>
20268 <entry role="func_table_entry"><para role="func_signature">
20269 <indexterm>
20270 <primary>count</primary>
20271 </indexterm>
20272 <function>count</function> ( <literal>*</literal> )
20273 <returnvalue>bigint</returnvalue>
20274 </para>
20275 <para>
20276 Computes the number of input rows.
20277 </para></entry>
20278 <entry>Yes</entry>
20279 </row>
20281 <row>
20282 <entry role="func_table_entry"><para role="func_signature">
20283 <function>count</function> ( <type>"any"</type> )
20284 <returnvalue>bigint</returnvalue>
20285 </para>
20286 <para>
20287 Computes the number of input rows in which the input value is not
20288 null.
20289 </para></entry>
20290 <entry>Yes</entry>
20291 </row>
20293 <row>
20294 <entry role="func_table_entry"><para role="func_signature">
20295 <indexterm>
20296 <primary>every</primary>
20297 </indexterm>
20298 <function>every</function> ( <type>boolean</type> )
20299 <returnvalue>boolean</returnvalue>
20300 </para>
20301 <para>
20302 This is the SQL standard's equivalent to <function>bool_and</function>.
20303 </para></entry>
20304 <entry>Yes</entry>
20305 </row>
20307 <row>
20308 <entry role="func_table_entry"><para role="func_signature">
20309 <indexterm>
20310 <primary>json_agg</primary>
20311 </indexterm>
20312 <function>json_agg</function> ( <type>anyelement</type> )
20313 <returnvalue>json</returnvalue>
20314 </para>
20315 <para role="func_signature">
20316 <indexterm>
20317 <primary>jsonb_agg</primary>
20318 </indexterm>
20319 <function>jsonb_agg</function> ( <type>anyelement</type> )
20320 <returnvalue>jsonb</returnvalue>
20321 </para>
20322 <para>
20323 Collects all the input values, including nulls, into a JSON array.
20324 Values are converted to JSON as per <function>to_json</function>
20325 or <function>to_jsonb</function>.
20326 </para></entry>
20327 <entry>No</entry>
20328 </row>
20330 <row>
20331 <entry role="func_table_entry"><para role="func_signature">
20332 <indexterm><primary>json_objectagg</primary></indexterm>
20333 <function>json_objectagg</function> (
20334 <optional> { <replaceable>key_expression</replaceable> { <literal>VALUE</literal> | ':' } <replaceable>value_expression</replaceable> } </optional>
20335 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
20336 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
20337 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
20338 </para>
20339 <para>
20340 Behaves like <function>json_object</function><!-- xref -->, but as an
20341 aggregate function, so it only takes one
20342 <replaceable>key_expression</replaceable> and one
20343 <replaceable>value_expression</replaceable> parameter.
20344 </para>
20345 <para>
20346 <literal>SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date + 1)) AS t(k,v)</literal>
20347 <returnvalue>{ "a" : "2022-05-10", "b" : "2022-05-11" }</returnvalue>
20348 </para></entry>
20349 <entry>No</entry>
20350 </row>
20352 <row>
20353 <entry role="func_table_entry"><para role="func_signature">
20354 <indexterm>
20355 <primary>json_object_agg</primary>
20356 </indexterm>
20357 <function>json_object_agg</function> ( <parameter>key</parameter>
20358 <type>"any"</type>, <parameter>value</parameter>
20359 <type>"any"</type> )
20360 <returnvalue>json</returnvalue>
20361 </para>
20362 <para role="func_signature">
20363 <indexterm>
20364 <primary>jsonb_object_agg</primary>
20365 </indexterm>
20366 <function>jsonb_object_agg</function> ( <parameter>key</parameter>
20367 <type>"any"</type>, <parameter>value</parameter>
20368 <type>"any"</type> )
20369 <returnvalue>jsonb</returnvalue>
20370 </para>
20371 <para>
20372 Collects all the key/value pairs into a JSON object. Key arguments
20373 are coerced to text; value arguments are converted as per
20374 <function>to_json</function> or <function>to_jsonb</function>.
20375 Values can be null, but keys cannot.
20376 </para></entry>
20377 <entry>No</entry>
20378 </row>
20380 <row>
20381 <entry role="func_table_entry"><para role="func_signature">
20382 <indexterm>
20383 <primary>json_object_agg_strict</primary>
20384 </indexterm>
20385 <function>json_object_agg_strict</function> (
20386 <parameter>key</parameter> <type>"any"</type>,
20387 <parameter>value</parameter> <type>"any"</type> )
20388 <returnvalue>json</returnvalue>
20389 </para>
20390 <para role="func_signature">
20391 <indexterm>
20392 <primary>jsonb_object_agg_strict</primary>
20393 </indexterm>
20394 <function>jsonb_object_agg_strict</function> (
20395 <parameter>key</parameter> <type>"any"</type>,
20396 <parameter>value</parameter> <type>"any"</type> )
20397 <returnvalue>jsonb</returnvalue>
20398 </para>
20399 <para>
20400 Collects all the key/value pairs into a JSON object. Key arguments
20401 are coerced to text; value arguments are converted as per
20402 <function>to_json</function> or <function>to_jsonb</function>.
20403 The <parameter>key</parameter> can not be null. If the
20404 <parameter>value</parameter> is null then the entry is skipped,
20405 </para></entry>
20406 <entry>No</entry>
20407 </row>
20409 <row>
20410 <entry role="func_table_entry"><para role="func_signature">
20411 <indexterm>
20412 <primary>json_object_agg_unique</primary>
20413 </indexterm>
20414 <function>json_object_agg_unique</function> (
20415 <parameter>key</parameter> <type>"any"</type>,
20416 <parameter>value</parameter> <type>"any"</type> )
20417 <returnvalue>json</returnvalue>
20418 </para>
20419 <para role="func_signature">
20420 <indexterm>
20421 <primary>jsonb_object_agg_unique</primary>
20422 </indexterm>
20423 <function>jsonb_object_agg_unique</function> (
20424 <parameter>key</parameter> <type>"any"</type>,
20425 <parameter>value</parameter> <type>"any"</type> )
20426 <returnvalue>jsonb</returnvalue>
20427 </para>
20428 <para>
20429 Collects all the key/value pairs into a JSON object. Key arguments
20430 are coerced to text; value arguments are converted as per
20431 <function>to_json</function> or <function>to_jsonb</function>.
20432 Values can be null, but keys cannot.
20433 If there is a duplicate key an error is thrown.
20434 </para></entry>
20435 <entry>No</entry>
20436 </row>
20438 <row>
20439 <entry role="func_table_entry"><para role="func_signature">
20440 <indexterm><primary>json_arrayagg</primary></indexterm>
20441 <function>json_arrayagg</function> (
20442 <optional> <replaceable>value_expression</replaceable> </optional>
20443 <optional> <literal>ORDER BY</literal> <replaceable>sort_expression</replaceable> </optional>
20444 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
20445 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
20446 </para>
20447 <para>
20448 Behaves in the same way as <function>json_array</function>
20449 but as an aggregate function so it only takes one
20450 <replaceable>value_expression</replaceable> parameter.
20451 If <literal>ABSENT ON NULL</literal> is specified, any NULL
20452 values are omitted.
20453 If <literal>ORDER BY</literal> is specified, the elements will
20454 appear in the array in that order rather than in the input order.
20455 </para>
20456 <para>
20457 <literal>SELECT json_arrayagg(v) FROM (VALUES(2),(1)) t(v)</literal>
20458 <returnvalue>[2, 1]</returnvalue>
20459 </para></entry>
20460 <entry>No</entry>
20461 </row>
20463 <row>
20464 <entry role="func_table_entry"><para role="func_signature">
20465 <indexterm>
20466 <primary>json_object_agg_unique_strict</primary>
20467 </indexterm>
20468 <function>json_object_agg_unique_strict</function> (
20469 <parameter>key</parameter> <type>"any"</type>,
20470 <parameter>value</parameter> <type>"any"</type> )
20471 <returnvalue>json</returnvalue>
20472 </para>
20473 <para role="func_signature">
20474 <indexterm>
20475 <primary>jsonb_object_agg_unique_strict</primary>
20476 </indexterm>
20477 <function>jsonb_object_agg_unique_strict</function> (
20478 <parameter>key</parameter> <type>"any"</type>,
20479 <parameter>value</parameter> <type>"any"</type> )
20480 <returnvalue>jsonb</returnvalue>
20481 </para>
20482 <para>
20483 Collects all the key/value pairs into a JSON object. Key arguments
20484 are coerced to text; value arguments are converted as per
20485 <function>to_json</function> or <function>to_jsonb</function>.
20486 The <parameter>key</parameter> can not be null. If the
20487 <parameter>value</parameter> is null then the entry is skipped.
20488 If there is a duplicate key an error is thrown.
20489 </para></entry>
20490 <entry>No</entry>
20491 </row>
20493 <row>
20494 <entry role="func_table_entry"><para role="func_signature">
20495 <indexterm>
20496 <primary>max</primary>
20497 </indexterm>
20498 <function>max</function> ( <replaceable>see text</replaceable> )
20499 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
20500 </para>
20501 <para>
20502 Computes the maximum of the non-null input
20503 values. Available for any numeric, string, date/time, or enum type,
20504 as well as <type>inet</type>, <type>interval</type>,
20505 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
20506 <type>tid</type>, <type>xid8</type>,
20507 and arrays of any of these types.
20508 </para></entry>
20509 <entry>Yes</entry>
20510 </row>
20512 <row>
20513 <entry role="func_table_entry"><para role="func_signature">
20514 <indexterm>
20515 <primary>min</primary>
20516 </indexterm>
20517 <function>min</function> ( <replaceable>see text</replaceable> )
20518 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
20519 </para>
20520 <para>
20521 Computes the minimum of the non-null input
20522 values. Available for any numeric, string, date/time, or enum type,
20523 as well as <type>inet</type>, <type>interval</type>,
20524 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
20525 <type>tid</type>, <type>xid8</type>,
20526 and arrays of any of these types.
20527 </para></entry>
20528 <entry>Yes</entry>
20529 </row>
20531 <row>
20532 <entry role="func_table_entry"><para role="func_signature">
20533 <indexterm>
20534 <primary>range_agg</primary>
20535 </indexterm>
20536 <function>range_agg</function> ( <parameter>value</parameter>
20537 <type>anyrange</type> )
20538 <returnvalue>anymultirange</returnvalue>
20539 </para>
20540 <para role="func_signature">
20541 <function>range_agg</function> ( <parameter>value</parameter>
20542 <type>anymultirange</type> )
20543 <returnvalue>anymultirange</returnvalue>
20544 </para>
20545 <para>
20546 Computes the union of the non-null input values.
20547 </para></entry>
20548 <entry>No</entry>
20549 </row>
20551 <row>
20552 <entry role="func_table_entry"><para role="func_signature">
20553 <indexterm>
20554 <primary>range_intersect_agg</primary>
20555 </indexterm>
20556 <function>range_intersect_agg</function> ( <parameter>value</parameter>
20557 <type>anyrange</type> )
20558 <returnvalue>anyrange</returnvalue>
20559 </para>
20560 <para role="func_signature">
20561 <function>range_intersect_agg</function> ( <parameter>value</parameter>
20562 <type>anymultirange</type> )
20563 <returnvalue>anymultirange</returnvalue>
20564 </para>
20565 <para>
20566 Computes the intersection of the non-null input values.
20567 </para></entry>
20568 <entry>No</entry>
20569 </row>
20571 <row>
20572 <entry role="func_table_entry"><para role="func_signature">
20573 <indexterm>
20574 <primary>json_agg_strict</primary>
20575 </indexterm>
20576 <function>json_agg_strict</function> ( <type>anyelement</type> )
20577 <returnvalue>json</returnvalue>
20578 </para>
20579 <para role="func_signature">
20580 <indexterm>
20581 <primary>jsonb_agg_strict</primary>
20582 </indexterm>
20583 <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
20584 <returnvalue>jsonb</returnvalue>
20585 </para>
20586 <para>
20587 Collects all the input values, skipping nulls, into a JSON array.
20588 Values are converted to JSON as per <function>to_json</function>
20589 or <function>to_jsonb</function>.
20590 </para></entry>
20591 <entry>No</entry>
20592 </row>
20594 <row>
20595 <entry role="func_table_entry"><para role="func_signature">
20596 <indexterm>
20597 <primary>string_agg</primary>
20598 </indexterm>
20599 <function>string_agg</function> ( <parameter>value</parameter>
20600 <type>text</type>, <parameter>delimiter</parameter> <type>text</type> )
20601 <returnvalue>text</returnvalue>
20602 </para>
20603 <para role="func_signature">
20604 <function>string_agg</function> ( <parameter>value</parameter>
20605 <type>bytea</type>, <parameter>delimiter</parameter> <type>bytea</type> )
20606 <returnvalue>bytea</returnvalue>
20607 </para>
20608 <para>
20609 Concatenates the non-null input values into a string. Each value
20610 after the first is preceded by the
20611 corresponding <parameter>delimiter</parameter> (if it's not null).
20612 </para></entry>
20613 <entry>Yes</entry>
20614 </row>
20616 <row>
20617 <entry role="func_table_entry"><para role="func_signature">
20618 <indexterm>
20619 <primary>sum</primary>
20620 </indexterm>
20621 <function>sum</function> ( <type>smallint</type> )
20622 <returnvalue>bigint</returnvalue>
20623 </para>
20624 <para role="func_signature">
20625 <function>sum</function> ( <type>integer</type> )
20626 <returnvalue>bigint</returnvalue>
20627 </para>
20628 <para role="func_signature">
20629 <function>sum</function> ( <type>bigint</type> )
20630 <returnvalue>numeric</returnvalue>
20631 </para>
20632 <para role="func_signature">
20633 <function>sum</function> ( <type>numeric</type> )
20634 <returnvalue>numeric</returnvalue>
20635 </para>
20636 <para role="func_signature">
20637 <function>sum</function> ( <type>real</type> )
20638 <returnvalue>real</returnvalue>
20639 </para>
20640 <para role="func_signature">
20641 <function>sum</function> ( <type>double precision</type> )
20642 <returnvalue>double precision</returnvalue>
20643 </para>
20644 <para role="func_signature">
20645 <function>sum</function> ( <type>interval</type> )
20646 <returnvalue>interval</returnvalue>
20647 </para>
20648 <para role="func_signature">
20649 <function>sum</function> ( <type>money</type> )
20650 <returnvalue>money</returnvalue>
20651 </para>
20652 <para>
20653 Computes the sum of the non-null input values.
20654 </para></entry>
20655 <entry>Yes</entry>
20656 </row>
20658 <row>
20659 <entry role="func_table_entry"><para role="func_signature">
20660 <indexterm>
20661 <primary>xmlagg</primary>
20662 </indexterm>
20663 <function>xmlagg</function> ( <type>xml</type> )
20664 <returnvalue>xml</returnvalue>
20665 </para>
20666 <para>
20667 Concatenates the non-null XML input values (see
20668 <xref linkend="functions-xml-xmlagg"/>).
20669 </para></entry>
20670 <entry>No</entry>
20671 </row>
20672 </tbody>
20673 </tgroup>
20674 </table>
20676 <para>
20677 It should be noted that except for <function>count</function>,
20678 these functions return a null value when no rows are selected. In
20679 particular, <function>sum</function> of no rows returns null, not
20680 zero as one might expect, and <function>array_agg</function>
20681 returns null rather than an empty array when there are no input
20682 rows. The <function>coalesce</function> function can be used to
20683 substitute zero or an empty array for null when necessary.
20684 </para>
20686 <para>
20687 The aggregate functions <function>array_agg</function>,
20688 <function>json_agg</function>, <function>jsonb_agg</function>,
20689 <function>json_agg_strict</function>, <function>jsonb_agg_strict</function>,
20690 <function>json_object_agg</function>, <function>jsonb_object_agg</function>,
20691 <function>json_object_agg_strict</function>, <function>jsonb_object_agg_strict</function>,
20692 <function>json_object_agg_unique</function>, <function>jsonb_object_agg_unique</function>,
20693 <function>json_object_agg_unique_strict</function>,
20694 <function>jsonb_object_agg_unique_strict</function>,
20695 <function>string_agg</function>,
20696 and <function>xmlagg</function>, as well as similar user-defined
20697 aggregate functions, produce meaningfully different result values
20698 depending on the order of the input values. This ordering is
20699 unspecified by default, but can be controlled by writing an
20700 <literal>ORDER BY</literal> clause within the aggregate call, as shown in
20701 <xref linkend="syntax-aggregates"/>.
20702 Alternatively, supplying the input values from a sorted subquery
20703 will usually work. For example:
20705 <screen><![CDATA[
20706 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
20707 ]]></screen>
20709 Beware that this approach can fail if the outer query level contains
20710 additional processing, such as a join, because that might cause the
20711 subquery's output to be reordered before the aggregate is computed.
20712 </para>
20714 <note>
20715 <indexterm>
20716 <primary>ANY</primary>
20717 </indexterm>
20718 <indexterm>
20719 <primary>SOME</primary>
20720 </indexterm>
20721 <para>
20722 The boolean aggregates <function>bool_and</function> and
20723 <function>bool_or</function> correspond to the standard SQL aggregates
20724 <function>every</function> and <function>any</function> or
20725 <function>some</function>.
20726 <productname>PostgreSQL</productname>
20727 supports <function>every</function>, but not <function>any</function>
20728 or <function>some</function>, because there is an ambiguity built into
20729 the standard syntax:
20730 <programlisting>
20731 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
20732 </programlisting>
20733 Here <function>ANY</function> can be considered either as introducing
20734 a subquery, or as being an aggregate function, if the subquery
20735 returns one row with a Boolean value.
20736 Thus the standard name cannot be given to these aggregates.
20737 </para>
20738 </note>
20740 <note>
20741 <para>
20742 Users accustomed to working with other SQL database management
20743 systems might be disappointed by the performance of the
20744 <function>count</function> aggregate when it is applied to the
20745 entire table. A query like:
20746 <programlisting>
20747 SELECT count(*) FROM sometable;
20748 </programlisting>
20749 will require effort proportional to the size of the table:
20750 <productname>PostgreSQL</productname> will need to scan either the
20751 entire table or the entirety of an index that includes all rows in
20752 the table.
20753 </para>
20754 </note>
20756 <para>
20757 <xref linkend="functions-aggregate-statistics-table"/> shows
20758 aggregate functions typically used in statistical analysis.
20759 (These are separated out merely to avoid cluttering the listing
20760 of more-commonly-used aggregates.) Functions shown as
20761 accepting <replaceable>numeric_type</replaceable> are available for all
20762 the types <type>smallint</type>, <type>integer</type>,
20763 <type>bigint</type>, <type>numeric</type>, <type>real</type>,
20764 and <type>double precision</type>.
20765 Where the description mentions
20766 <parameter>N</parameter>, it means the
20767 number of input rows for which all the input expressions are non-null.
20768 In all cases, null is returned if the computation is meaningless,
20769 for example when <parameter>N</parameter> is zero.
20770 </para>
20772 <indexterm>
20773 <primary>statistics</primary>
20774 </indexterm>
20775 <indexterm>
20776 <primary>linear regression</primary>
20777 </indexterm>
20779 <table id="functions-aggregate-statistics-table">
20780 <title>Aggregate Functions for Statistics</title>
20781 <tgroup cols="2">
20782 <colspec colname="col1" colwidth="10*"/>
20783 <colspec colname="col2" colwidth="1*"/>
20784 <thead>
20785 <row>
20786 <entry role="func_table_entry"><para role="func_signature">
20787 Function
20788 </para>
20789 <para>
20790 Description
20791 </para></entry>
20792 <entry>Partial Mode</entry>
20793 </row>
20794 </thead>
20796 <tbody>
20797 <row>
20798 <entry role="func_table_entry"><para role="func_signature">
20799 <indexterm>
20800 <primary>correlation</primary>
20801 </indexterm>
20802 <indexterm>
20803 <primary>corr</primary>
20804 </indexterm>
20805 <function>corr</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20806 <returnvalue>double precision</returnvalue>
20807 </para>
20808 <para>
20809 Computes the correlation coefficient.
20810 </para></entry>
20811 <entry>Yes</entry>
20812 </row>
20814 <row>
20815 <entry role="func_table_entry"><para role="func_signature">
20816 <indexterm>
20817 <primary>covariance</primary>
20818 <secondary>population</secondary>
20819 </indexterm>
20820 <indexterm>
20821 <primary>covar_pop</primary>
20822 </indexterm>
20823 <function>covar_pop</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20824 <returnvalue>double precision</returnvalue>
20825 </para>
20826 <para>
20827 Computes the population covariance.
20828 </para></entry>
20829 <entry>Yes</entry>
20830 </row>
20832 <row>
20833 <entry role="func_table_entry"><para role="func_signature">
20834 <indexterm>
20835 <primary>covariance</primary>
20836 <secondary>sample</secondary>
20837 </indexterm>
20838 <indexterm>
20839 <primary>covar_samp</primary>
20840 </indexterm>
20841 <function>covar_samp</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20842 <returnvalue>double precision</returnvalue>
20843 </para>
20844 <para>
20845 Computes the sample covariance.
20846 </para></entry>
20847 <entry>Yes</entry>
20848 </row>
20850 <row>
20851 <entry role="func_table_entry"><para role="func_signature">
20852 <indexterm>
20853 <primary>regr_avgx</primary>
20854 </indexterm>
20855 <function>regr_avgx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20856 <returnvalue>double precision</returnvalue>
20857 </para>
20858 <para>
20859 Computes the average of the independent variable,
20860 <literal>sum(<parameter>X</parameter>)/<parameter>N</parameter></literal>.
20861 </para></entry>
20862 <entry>Yes</entry>
20863 </row>
20865 <row>
20866 <entry role="func_table_entry"><para role="func_signature">
20867 <indexterm>
20868 <primary>regr_avgy</primary>
20869 </indexterm>
20870 <function>regr_avgy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20871 <returnvalue>double precision</returnvalue>
20872 </para>
20873 <para>
20874 Computes the average of the dependent variable,
20875 <literal>sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
20876 </para></entry>
20877 <entry>Yes</entry>
20878 </row>
20880 <row>
20881 <entry role="func_table_entry"><para role="func_signature">
20882 <indexterm>
20883 <primary>regr_count</primary>
20884 </indexterm>
20885 <function>regr_count</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20886 <returnvalue>bigint</returnvalue>
20887 </para>
20888 <para>
20889 Computes the number of rows in which both inputs are non-null.
20890 </para></entry>
20891 <entry>Yes</entry>
20892 </row>
20894 <row>
20895 <entry role="func_table_entry"><para role="func_signature">
20896 <indexterm>
20897 <primary>regression intercept</primary>
20898 </indexterm>
20899 <indexterm>
20900 <primary>regr_intercept</primary>
20901 </indexterm>
20902 <function>regr_intercept</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20903 <returnvalue>double precision</returnvalue>
20904 </para>
20905 <para>
20906 Computes the y-intercept of the least-squares-fit linear equation
20907 determined by the
20908 (<parameter>X</parameter>, <parameter>Y</parameter>) pairs.
20909 </para></entry>
20910 <entry>Yes</entry>
20911 </row>
20913 <row>
20914 <entry role="func_table_entry"><para role="func_signature">
20915 <indexterm>
20916 <primary>regr_r2</primary>
20917 </indexterm>
20918 <function>regr_r2</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20919 <returnvalue>double precision</returnvalue>
20920 </para>
20921 <para>
20922 Computes the square of the correlation coefficient.
20923 </para></entry>
20924 <entry>Yes</entry>
20925 </row>
20927 <row>
20928 <entry role="func_table_entry"><para role="func_signature">
20929 <indexterm>
20930 <primary>regression slope</primary>
20931 </indexterm>
20932 <indexterm>
20933 <primary>regr_slope</primary>
20934 </indexterm>
20935 <function>regr_slope</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20936 <returnvalue>double precision</returnvalue>
20937 </para>
20938 <para>
20939 Computes the slope of the least-squares-fit linear equation determined
20940 by the (<parameter>X</parameter>, <parameter>Y</parameter>)
20941 pairs.
20942 </para></entry>
20943 <entry>Yes</entry>
20944 </row>
20946 <row>
20947 <entry role="func_table_entry"><para role="func_signature">
20948 <indexterm>
20949 <primary>regr_sxx</primary>
20950 </indexterm>
20951 <function>regr_sxx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20952 <returnvalue>double precision</returnvalue>
20953 </para>
20954 <para>
20955 Computes the <quote>sum of squares</quote> of the independent
20956 variable,
20957 <literal>sum(<parameter>X</parameter>^2) - sum(<parameter>X</parameter>)^2/<parameter>N</parameter></literal>.
20958 </para></entry>
20959 <entry>Yes</entry>
20960 </row>
20962 <row>
20963 <entry role="func_table_entry"><para role="func_signature">
20964 <indexterm>
20965 <primary>regr_sxy</primary>
20966 </indexterm>
20967 <function>regr_sxy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20968 <returnvalue>double precision</returnvalue>
20969 </para>
20970 <para>
20971 Computes the <quote>sum of products</quote> of independent times
20972 dependent variables,
20973 <literal>sum(<parameter>X</parameter>*<parameter>Y</parameter>) - sum(<parameter>X</parameter>) * sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
20974 </para></entry>
20975 <entry>Yes</entry>
20976 </row>
20978 <row>
20979 <entry role="func_table_entry"><para role="func_signature">
20980 <indexterm>
20981 <primary>regr_syy</primary>
20982 </indexterm>
20983 <function>regr_syy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
20984 <returnvalue>double precision</returnvalue>
20985 </para>
20986 <para>
20987 Computes the <quote>sum of squares</quote> of the dependent
20988 variable,
20989 <literal>sum(<parameter>Y</parameter>^2) - sum(<parameter>Y</parameter>)^2/<parameter>N</parameter></literal>.
20990 </para></entry>
20991 <entry>Yes</entry>
20992 </row>
20994 <row>
20995 <entry role="func_table_entry"><para role="func_signature">
20996 <indexterm>
20997 <primary>standard deviation</primary>
20998 </indexterm>
20999 <indexterm>
21000 <primary>stddev</primary>
21001 </indexterm>
21002 <function>stddev</function> ( <replaceable>numeric_type</replaceable> )
21003 <returnvalue></returnvalue> <type>double precision</type>
21004 for <type>real</type> or <type>double precision</type>,
21005 otherwise <type>numeric</type>
21006 </para>
21007 <para>
21008 This is a historical alias for <function>stddev_samp</function>.
21009 </para></entry>
21010 <entry>Yes</entry>
21011 </row>
21013 <row>
21014 <entry role="func_table_entry"><para role="func_signature">
21015 <indexterm>
21016 <primary>standard deviation</primary>
21017 <secondary>population</secondary>
21018 </indexterm>
21019 <indexterm>
21020 <primary>stddev_pop</primary>
21021 </indexterm>
21022 <function>stddev_pop</function> ( <replaceable>numeric_type</replaceable> )
21023 <returnvalue></returnvalue> <type>double precision</type>
21024 for <type>real</type> or <type>double precision</type>,
21025 otherwise <type>numeric</type>
21026 </para>
21027 <para>
21028 Computes the population standard deviation of the input values.
21029 </para></entry>
21030 <entry>Yes</entry>
21031 </row>
21033 <row>
21034 <entry role="func_table_entry"><para role="func_signature">
21035 <indexterm>
21036 <primary>standard deviation</primary>
21037 <secondary>sample</secondary>
21038 </indexterm>
21039 <indexterm>
21040 <primary>stddev_samp</primary>
21041 </indexterm>
21042 <function>stddev_samp</function> ( <replaceable>numeric_type</replaceable> )
21043 <returnvalue></returnvalue> <type>double precision</type>
21044 for <type>real</type> or <type>double precision</type>,
21045 otherwise <type>numeric</type>
21046 </para>
21047 <para>
21048 Computes the sample standard deviation of the input values.
21049 </para></entry>
21050 <entry>Yes</entry>
21051 </row>
21053 <row>
21054 <entry role="func_table_entry"><para role="func_signature">
21055 <indexterm>
21056 <primary>variance</primary>
21057 </indexterm>
21058 <function>variance</function> ( <replaceable>numeric_type</replaceable> )
21059 <returnvalue></returnvalue> <type>double precision</type>
21060 for <type>real</type> or <type>double precision</type>,
21061 otherwise <type>numeric</type>
21062 </para>
21063 <para>
21064 This is a historical alias for <function>var_samp</function>.
21065 </para></entry>
21066 <entry>Yes</entry>
21067 </row>
21069 <row>
21070 <entry role="func_table_entry"><para role="func_signature">
21071 <indexterm>
21072 <primary>variance</primary>
21073 <secondary>population</secondary>
21074 </indexterm>
21075 <indexterm>
21076 <primary>var_pop</primary>
21077 </indexterm>
21078 <function>var_pop</function> ( <replaceable>numeric_type</replaceable> )
21079 <returnvalue></returnvalue> <type>double precision</type>
21080 for <type>real</type> or <type>double precision</type>,
21081 otherwise <type>numeric</type>
21082 </para>
21083 <para>
21084 Computes the population variance of the input values (square of the
21085 population standard deviation).
21086 </para></entry>
21087 <entry>Yes</entry>
21088 </row>
21090 <row>
21091 <entry role="func_table_entry"><para role="func_signature">
21092 <indexterm>
21093 <primary>variance</primary>
21094 <secondary>sample</secondary>
21095 </indexterm>
21096 <indexterm>
21097 <primary>var_samp</primary>
21098 </indexterm>
21099 <function>var_samp</function> ( <replaceable>numeric_type</replaceable> )
21100 <returnvalue></returnvalue> <type>double precision</type>
21101 for <type>real</type> or <type>double precision</type>,
21102 otherwise <type>numeric</type>
21103 </para>
21104 <para>
21105 Computes the sample variance of the input values (square of the sample
21106 standard deviation).
21107 </para></entry>
21108 <entry>Yes</entry>
21109 </row>
21110 </tbody>
21111 </tgroup>
21112 </table>
21114 <para>
21115 <xref linkend="functions-orderedset-table"/> shows some
21116 aggregate functions that use the <firstterm>ordered-set aggregate</firstterm>
21117 syntax. These functions are sometimes referred to as <quote>inverse
21118 distribution</quote> functions. Their aggregated input is introduced by
21119 <literal>ORDER BY</literal>, and they may also take a <firstterm>direct
21120 argument</firstterm> that is not aggregated, but is computed only once.
21121 All these functions ignore null values in their aggregated input.
21122 For those that take a <parameter>fraction</parameter> parameter, the
21123 fraction value must be between 0 and 1; an error is thrown if not.
21124 However, a null <parameter>fraction</parameter> value simply produces a
21125 null result.
21126 </para>
21128 <indexterm>
21129 <primary>ordered-set aggregate</primary>
21130 <secondary>built-in</secondary>
21131 </indexterm>
21132 <indexterm>
21133 <primary>inverse distribution</primary>
21134 </indexterm>
21136 <table id="functions-orderedset-table">
21137 <title>Ordered-Set Aggregate Functions</title>
21138 <tgroup cols="2">
21139 <colspec colname="col1" colwidth="10*"/>
21140 <colspec colname="col2" colwidth="1*"/>
21141 <thead>
21142 <row>
21143 <entry role="func_table_entry"><para role="func_signature">
21144 Function
21145 </para>
21146 <para>
21147 Description
21148 </para></entry>
21149 <entry>Partial Mode</entry>
21150 </row>
21151 </thead>
21153 <tbody>
21154 <row>
21155 <entry role="func_table_entry"><para role="func_signature">
21156 <indexterm>
21157 <primary>mode</primary>
21158 <secondary>statistical</secondary>
21159 </indexterm>
21160 <function>mode</function> () <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21161 <returnvalue>anyelement</returnvalue>
21162 </para>
21163 <para>
21164 Computes the <firstterm>mode</firstterm>, the most frequent
21165 value of the aggregated argument (arbitrarily choosing the first one
21166 if there are multiple equally-frequent values). The aggregated
21167 argument must be of a sortable type.
21168 </para></entry>
21169 <entry>No</entry>
21170 </row>
21172 <row>
21173 <entry role="func_table_entry"><para role="func_signature">
21174 <indexterm>
21175 <primary>percentile</primary>
21176 <secondary>continuous</secondary>
21177 </indexterm>
21178 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
21179 <returnvalue>double precision</returnvalue>
21180 </para>
21181 <para role="func_signature">
21182 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
21183 <returnvalue>interval</returnvalue>
21184 </para>
21185 <para>
21186 Computes the <firstterm>continuous percentile</firstterm>, a value
21187 corresponding to the specified <parameter>fraction</parameter>
21188 within the ordered set of aggregated argument values. This will
21189 interpolate between adjacent input items if needed.
21190 </para></entry>
21191 <entry>No</entry>
21192 </row>
21194 <row>
21195 <entry role="func_table_entry"><para role="func_signature">
21196 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
21197 <returnvalue>double precision[]</returnvalue>
21198 </para>
21199 <para role="func_signature">
21200 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
21201 <returnvalue>interval[]</returnvalue>
21202 </para>
21203 <para>
21204 Computes multiple continuous percentiles. The result is an array of
21205 the same dimensions as the <parameter>fractions</parameter>
21206 parameter, with each non-null element replaced by the (possibly
21207 interpolated) value corresponding to that percentile.
21208 </para></entry>
21209 <entry>No</entry>
21210 </row>
21212 <row>
21213 <entry role="func_table_entry"><para role="func_signature">
21214 <indexterm>
21215 <primary>percentile</primary>
21216 <secondary>discrete</secondary>
21217 </indexterm>
21218 <function>percentile_disc</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21219 <returnvalue>anyelement</returnvalue>
21220 </para>
21221 <para>
21222 Computes the <firstterm>discrete percentile</firstterm>, the first
21223 value within the ordered set of aggregated argument values whose
21224 position in the ordering equals or exceeds the
21225 specified <parameter>fraction</parameter>. The aggregated
21226 argument must be of a sortable type.
21227 </para></entry>
21228 <entry>No</entry>
21229 </row>
21231 <row>
21232 <entry role="func_table_entry"><para role="func_signature">
21233 <function>percentile_disc</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21234 <returnvalue>anyarray</returnvalue>
21235 </para>
21236 <para>
21237 Computes multiple discrete percentiles. The result is an array of the
21238 same dimensions as the <parameter>fractions</parameter> parameter,
21239 with each non-null element replaced by the input value corresponding
21240 to that percentile.
21241 The aggregated argument must be of a sortable type.
21242 </para></entry>
21243 <entry>No</entry>
21244 </row>
21245 </tbody>
21246 </tgroup>
21247 </table>
21249 <indexterm>
21250 <primary>hypothetical-set aggregate</primary>
21251 <secondary>built-in</secondary>
21252 </indexterm>
21254 <para>
21255 Each of the <quote>hypothetical-set</quote> aggregates listed in
21256 <xref linkend="functions-hypothetical-table"/> is associated with a
21257 window function of the same name defined in
21258 <xref linkend="functions-window"/>. In each case, the aggregate's result
21259 is the value that the associated window function would have
21260 returned for the <quote>hypothetical</quote> row constructed from
21261 <replaceable>args</replaceable>, if such a row had been added to the sorted
21262 group of rows represented by the <replaceable>sorted_args</replaceable>.
21263 For each of these functions, the list of direct arguments
21264 given in <replaceable>args</replaceable> must match the number and types of
21265 the aggregated arguments given in <replaceable>sorted_args</replaceable>.
21266 Unlike most built-in aggregates, these aggregates are not strict, that is
21267 they do not drop input rows containing nulls. Null values sort according
21268 to the rule specified in the <literal>ORDER BY</literal> clause.
21269 </para>
21271 <table id="functions-hypothetical-table">
21272 <title>Hypothetical-Set Aggregate Functions</title>
21273 <tgroup cols="2">
21274 <colspec colname="col1" colwidth="10*"/>
21275 <colspec colname="col2" colwidth="1*"/>
21276 <thead>
21277 <row>
21278 <entry role="func_table_entry"><para role="func_signature">
21279 Function
21280 </para>
21281 <para>
21282 Description
21283 </para></entry>
21284 <entry>Partial Mode</entry>
21285 </row>
21286 </thead>
21288 <tbody>
21289 <row>
21290 <entry role="func_table_entry"><para role="func_signature">
21291 <indexterm>
21292 <primary>rank</primary>
21293 <secondary>hypothetical</secondary>
21294 </indexterm>
21295 <function>rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21296 <returnvalue>bigint</returnvalue>
21297 </para>
21298 <para>
21299 Computes the rank of the hypothetical row, with gaps; that is, the row
21300 number of the first row in its peer group.
21301 </para></entry>
21302 <entry>No</entry>
21303 </row>
21305 <row>
21306 <entry role="func_table_entry"><para role="func_signature">
21307 <indexterm>
21308 <primary>dense_rank</primary>
21309 <secondary>hypothetical</secondary>
21310 </indexterm>
21311 <function>dense_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21312 <returnvalue>bigint</returnvalue>
21313 </para>
21314 <para>
21315 Computes the rank of the hypothetical row, without gaps; this function
21316 effectively counts peer groups.
21317 </para></entry>
21318 <entry>No</entry>
21319 </row>
21321 <row>
21322 <entry role="func_table_entry"><para role="func_signature">
21323 <indexterm>
21324 <primary>percent_rank</primary>
21325 <secondary>hypothetical</secondary>
21326 </indexterm>
21327 <function>percent_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21328 <returnvalue>double precision</returnvalue>
21329 </para>
21330 <para>
21331 Computes the relative rank of the hypothetical row, that is
21332 (<function>rank</function> - 1) / (total rows - 1).
21333 The value thus ranges from 0 to 1 inclusive.
21334 </para></entry>
21335 <entry>No</entry>
21336 </row>
21338 <row>
21339 <entry role="func_table_entry"><para role="func_signature">
21340 <indexterm>
21341 <primary>cume_dist</primary>
21342 <secondary>hypothetical</secondary>
21343 </indexterm>
21344 <function>cume_dist</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21345 <returnvalue>double precision</returnvalue>
21346 </para>
21347 <para>
21348 Computes the cumulative distribution, that is (number of rows
21349 preceding or peers with hypothetical row) / (total rows). The value
21350 thus ranges from 1/<parameter>N</parameter> to 1.
21351 </para></entry>
21352 <entry>No</entry>
21353 </row>
21354 </tbody>
21355 </tgroup>
21356 </table>
21358 <table id="functions-grouping-table">
21359 <title>Grouping Operations</title>
21360 <tgroup cols="1">
21361 <thead>
21362 <row>
21363 <entry role="func_table_entry"><para role="func_signature">
21364 Function
21365 </para>
21366 <para>
21367 Description
21368 </para></entry>
21369 </row>
21370 </thead>
21372 <tbody>
21373 <row>
21374 <entry role="func_table_entry"><para role="func_signature">
21375 <indexterm>
21376 <primary>GROUPING</primary>
21377 </indexterm>
21378 <function>GROUPING</function> ( <replaceable>group_by_expression(s)</replaceable> )
21379 <returnvalue>integer</returnvalue>
21380 </para>
21381 <para>
21382 Returns a bit mask indicating which <literal>GROUP BY</literal>
21383 expressions are not included in the current grouping set.
21384 Bits are assigned with the rightmost argument corresponding to the
21385 least-significant bit; each bit is 0 if the corresponding expression
21386 is included in the grouping criteria of the grouping set generating
21387 the current result row, and 1 if it is not included.
21388 </para></entry>
21389 </row>
21390 </tbody>
21391 </tgroup>
21392 </table>
21394 <para>
21395 The grouping operations shown in
21396 <xref linkend="functions-grouping-table"/> are used in conjunction with
21397 grouping sets (see <xref linkend="queries-grouping-sets"/>) to distinguish
21398 result rows. The arguments to the <literal>GROUPING</literal> function
21399 are not actually evaluated, but they must exactly match expressions given
21400 in the <literal>GROUP BY</literal> clause of the associated query level.
21401 For example:
21402 <screen>
21403 <prompt>=&gt;</prompt> <userinput>SELECT * FROM items_sold;</userinput>
21404 make | model | sales
21405 -------+-------+-------
21406 Foo | GT | 10
21407 Foo | Tour | 20
21408 Bar | City | 15
21409 Bar | Sport | 5
21410 (4 rows)
21412 <prompt>=&gt;</prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</userinput>
21413 make | model | grouping | sum
21414 -------+-------+----------+-----
21415 Foo | GT | 0 | 10
21416 Foo | Tour | 0 | 20
21417 Bar | City | 0 | 15
21418 Bar | Sport | 0 | 5
21419 Foo | | 1 | 30
21420 Bar | | 1 | 20
21421 | | 3 | 50
21422 (7 rows)
21423 </screen>
21424 Here, the <literal>grouping</literal> value <literal>0</literal> in the
21425 first four rows shows that those have been grouped normally, over both the
21426 grouping columns. The value <literal>1</literal> indicates
21427 that <literal>model</literal> was not grouped by in the next-to-last two
21428 rows, and the value <literal>3</literal> indicates that
21429 neither <literal>make</literal> nor <literal>model</literal> was grouped
21430 by in the last row (which therefore is an aggregate over all the input
21431 rows).
21432 </para>
21434 </sect1>
21436 <sect1 id="functions-window">
21437 <title>Window Functions</title>
21439 <indexterm zone="functions-window">
21440 <primary>window function</primary>
21441 <secondary>built-in</secondary>
21442 </indexterm>
21444 <para>
21445 <firstterm>Window functions</firstterm> provide the ability to perform
21446 calculations across sets of rows that are related to the current query
21447 row. See <xref linkend="tutorial-window"/> for an introduction to this
21448 feature, and <xref linkend="syntax-window-functions"/> for syntax
21449 details.
21450 </para>
21452 <para>
21453 The built-in window functions are listed in
21454 <xref linkend="functions-window-table"/>. Note that these functions
21455 <emphasis>must</emphasis> be invoked using window function syntax, i.e., an
21456 <literal>OVER</literal> clause is required.
21457 </para>
21459 <para>
21460 In addition to these functions, any built-in or user-defined
21461 ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates)
21462 can be used as a window function; see
21463 <xref linkend="functions-aggregate"/> for a list of the built-in aggregates.
21464 Aggregate functions act as window functions only when an <literal>OVER</literal>
21465 clause follows the call; otherwise they act as plain aggregates
21466 and return a single row for the entire set.
21467 </para>
21469 <table id="functions-window-table">
21470 <title>General-Purpose Window Functions</title>
21471 <tgroup cols="1">
21472 <thead>
21473 <row>
21474 <entry role="func_table_entry"><para role="func_signature">
21475 Function
21476 </para>
21477 <para>
21478 Description
21479 </para></entry>
21480 </row>
21481 </thead>
21483 <tbody>
21484 <row>
21485 <entry role="func_table_entry"><para role="func_signature">
21486 <indexterm>
21487 <primary>row_number</primary>
21488 </indexterm>
21489 <function>row_number</function> ()
21490 <returnvalue>bigint</returnvalue>
21491 </para>
21492 <para>
21493 Returns the number of the current row within its partition, counting
21494 from 1.
21495 </para></entry>
21496 </row>
21498 <row>
21499 <entry role="func_table_entry"><para role="func_signature">
21500 <indexterm>
21501 <primary>rank</primary>
21502 </indexterm>
21503 <function>rank</function> ()
21504 <returnvalue>bigint</returnvalue>
21505 </para>
21506 <para>
21507 Returns the rank of the current row, with gaps; that is,
21508 the <function>row_number</function> of the first row in its peer
21509 group.
21510 </para></entry>
21511 </row>
21513 <row>
21514 <entry role="func_table_entry"><para role="func_signature">
21515 <indexterm>
21516 <primary>dense_rank</primary>
21517 </indexterm>
21518 <function>dense_rank</function> ()
21519 <returnvalue>bigint</returnvalue>
21520 </para>
21521 <para>
21522 Returns the rank of the current row, without gaps; this function
21523 effectively counts peer groups.
21524 </para></entry>
21525 </row>
21527 <row>
21528 <entry role="func_table_entry"><para role="func_signature">
21529 <indexterm>
21530 <primary>percent_rank</primary>
21531 </indexterm>
21532 <function>percent_rank</function> ()
21533 <returnvalue>double precision</returnvalue>
21534 </para>
21535 <para>
21536 Returns the relative rank of the current row, that is
21537 (<function>rank</function> - 1) / (total partition rows - 1).
21538 The value thus ranges from 0 to 1 inclusive.
21539 </para></entry>
21540 </row>
21542 <row>
21543 <entry role="func_table_entry"><para role="func_signature">
21544 <indexterm>
21545 <primary>cume_dist</primary>
21546 </indexterm>
21547 <function>cume_dist</function> ()
21548 <returnvalue>double precision</returnvalue>
21549 </para>
21550 <para>
21551 Returns the cumulative distribution, that is (number of partition rows
21552 preceding or peers with current row) / (total partition rows).
21553 The value thus ranges from 1/<parameter>N</parameter> to 1.
21554 </para></entry>
21555 </row>
21557 <row>
21558 <entry role="func_table_entry"><para role="func_signature">
21559 <indexterm>
21560 <primary>ntile</primary>
21561 </indexterm>
21562 <function>ntile</function> ( <parameter>num_buckets</parameter> <type>integer</type> )
21563 <returnvalue>integer</returnvalue>
21564 </para>
21565 <para>
21566 Returns an integer ranging from 1 to the argument value, dividing the
21567 partition as equally as possible.
21568 </para></entry>
21569 </row>
21571 <row>
21572 <entry role="func_table_entry"><para role="func_signature">
21573 <indexterm>
21574 <primary>lag</primary>
21575 </indexterm>
21576 <function>lag</function> ( <parameter>value</parameter> <type>anycompatible</type>
21577 <optional>, <parameter>offset</parameter> <type>integer</type>
21578 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
21579 <returnvalue>anycompatible</returnvalue>
21580 </para>
21581 <para>
21582 Returns <parameter>value</parameter> evaluated at
21583 the row that is <parameter>offset</parameter>
21584 rows before the current row within the partition; if there is no such
21585 row, instead returns <parameter>default</parameter>
21586 (which must be of a type compatible with
21587 <parameter>value</parameter>).
21588 Both <parameter>offset</parameter> and
21589 <parameter>default</parameter> are evaluated
21590 with respect to the current row. If omitted,
21591 <parameter>offset</parameter> defaults to 1 and
21592 <parameter>default</parameter> to <literal>NULL</literal>.
21593 </para></entry>
21594 </row>
21596 <row>
21597 <entry role="func_table_entry"><para role="func_signature">
21598 <indexterm>
21599 <primary>lead</primary>
21600 </indexterm>
21601 <function>lead</function> ( <parameter>value</parameter> <type>anycompatible</type>
21602 <optional>, <parameter>offset</parameter> <type>integer</type>
21603 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
21604 <returnvalue>anycompatible</returnvalue>
21605 </para>
21606 <para>
21607 Returns <parameter>value</parameter> evaluated at
21608 the row that is <parameter>offset</parameter>
21609 rows after the current row within the partition; if there is no such
21610 row, instead returns <parameter>default</parameter>
21611 (which must be of a type compatible with
21612 <parameter>value</parameter>).
21613 Both <parameter>offset</parameter> and
21614 <parameter>default</parameter> are evaluated
21615 with respect to the current row. If omitted,
21616 <parameter>offset</parameter> defaults to 1 and
21617 <parameter>default</parameter> to <literal>NULL</literal>.
21618 </para></entry>
21619 </row>
21621 <row>
21622 <entry role="func_table_entry"><para role="func_signature">
21623 <indexterm>
21624 <primary>first_value</primary>
21625 </indexterm>
21626 <function>first_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
21627 <returnvalue>anyelement</returnvalue>
21628 </para>
21629 <para>
21630 Returns <parameter>value</parameter> evaluated
21631 at the row that is the first row of the window frame.
21632 </para></entry>
21633 </row>
21635 <row>
21636 <entry role="func_table_entry"><para role="func_signature">
21637 <indexterm>
21638 <primary>last_value</primary>
21639 </indexterm>
21640 <function>last_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
21641 <returnvalue>anyelement</returnvalue>
21642 </para>
21643 <para>
21644 Returns <parameter>value</parameter> evaluated
21645 at the row that is the last row of the window frame.
21646 </para></entry>
21647 </row>
21649 <row>
21650 <entry role="func_table_entry"><para role="func_signature">
21651 <indexterm>
21652 <primary>nth_value</primary>
21653 </indexterm>
21654 <function>nth_value</function> ( <parameter>value</parameter> <type>anyelement</type>, <parameter>n</parameter> <type>integer</type> )
21655 <returnvalue>anyelement</returnvalue>
21656 </para>
21657 <para>
21658 Returns <parameter>value</parameter> evaluated
21659 at the row that is the <parameter>n</parameter>'th
21660 row of the window frame (counting from 1);
21661 returns <literal>NULL</literal> if there is no such row.
21662 </para></entry>
21663 </row>
21664 </tbody>
21665 </tgroup>
21666 </table>
21668 <para>
21669 All of the functions listed in
21670 <xref linkend="functions-window-table"/> depend on the sort ordering
21671 specified by the <literal>ORDER BY</literal> clause of the associated window
21672 definition. Rows that are not distinct when considering only the
21673 <literal>ORDER BY</literal> columns are said to be <firstterm>peers</firstterm>.
21674 The four ranking functions (including <function>cume_dist</function>) are
21675 defined so that they give the same answer for all rows of a peer group.
21676 </para>
21678 <para>
21679 Note that <function>first_value</function>, <function>last_value</function>, and
21680 <function>nth_value</function> consider only the rows within the <quote>window
21681 frame</quote>, which by default contains the rows from the start of the
21682 partition through the last peer of the current row. This is
21683 likely to give unhelpful results for <function>last_value</function> and
21684 sometimes also <function>nth_value</function>. You can redefine the frame by
21685 adding a suitable frame specification (<literal>RANGE</literal>,
21686 <literal>ROWS</literal> or <literal>GROUPS</literal>) to
21687 the <literal>OVER</literal> clause.
21688 See <xref linkend="syntax-window-functions"/> for more information
21689 about frame specifications.
21690 </para>
21692 <para>
21693 When an aggregate function is used as a window function, it aggregates
21694 over the rows within the current row's window frame.
21695 An aggregate used with <literal>ORDER BY</literal> and the default window frame
21696 definition produces a <quote>running sum</quote> type of behavior, which may or
21697 may not be what's wanted. To obtain
21698 aggregation over the whole partition, omit <literal>ORDER BY</literal> or use
21699 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</literal>.
21700 Other frame specifications can be used to obtain other effects.
21701 </para>
21703 <note>
21704 <para>
21705 The SQL standard defines a <literal>RESPECT NULLS</literal> or
21706 <literal>IGNORE NULLS</literal> option for <function>lead</function>, <function>lag</function>,
21707 <function>first_value</function>, <function>last_value</function>, and
21708 <function>nth_value</function>. This is not implemented in
21709 <productname>PostgreSQL</productname>: the behavior is always the
21710 same as the standard's default, namely <literal>RESPECT NULLS</literal>.
21711 Likewise, the standard's <literal>FROM FIRST</literal> or <literal>FROM LAST</literal>
21712 option for <function>nth_value</function> is not implemented: only the
21713 default <literal>FROM FIRST</literal> behavior is supported. (You can achieve
21714 the result of <literal>FROM LAST</literal> by reversing the <literal>ORDER BY</literal>
21715 ordering.)
21716 </para>
21717 </note>
21719 </sect1>
21721 <sect1 id="functions-subquery">
21722 <title>Subquery Expressions</title>
21724 <indexterm>
21725 <primary>EXISTS</primary>
21726 </indexterm>
21728 <indexterm>
21729 <primary>IN</primary>
21730 </indexterm>
21732 <indexterm>
21733 <primary>NOT IN</primary>
21734 </indexterm>
21736 <indexterm>
21737 <primary>ANY</primary>
21738 </indexterm>
21740 <indexterm>
21741 <primary>ALL</primary>
21742 </indexterm>
21744 <indexterm>
21745 <primary>SOME</primary>
21746 </indexterm>
21748 <indexterm>
21749 <primary>subquery</primary>
21750 </indexterm>
21752 <para>
21753 This section describes the <acronym>SQL</acronym>-compliant subquery
21754 expressions available in <productname>PostgreSQL</productname>.
21755 All of the expression forms documented in this section return
21756 Boolean (true/false) results.
21757 </para>
21759 <sect2 id="functions-subquery-exists">
21760 <title><literal>EXISTS</literal></title>
21762 <synopsis>
21763 EXISTS (<replaceable>subquery</replaceable>)
21764 </synopsis>
21766 <para>
21767 The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</command> statement,
21768 or <firstterm>subquery</firstterm>. The
21769 subquery is evaluated to determine whether it returns any rows.
21770 If it returns at least one row, the result of <token>EXISTS</token> is
21771 <quote>true</quote>; if the subquery returns no rows, the result of <token>EXISTS</token>
21772 is <quote>false</quote>.
21773 </para>
21775 <para>
21776 The subquery can refer to variables from the surrounding query,
21777 which will act as constants during any one evaluation of the subquery.
21778 </para>
21780 <para>
21781 The subquery will generally only be executed long enough to determine
21782 whether at least one row is returned, not all the way to completion.
21783 It is unwise to write a subquery that has side effects (such as
21784 calling sequence functions); whether the side effects occur
21785 might be unpredictable.
21786 </para>
21788 <para>
21789 Since the result depends only on whether any rows are returned,
21790 and not on the contents of those rows, the output list of the
21791 subquery is normally unimportant. A common coding convention is
21792 to write all <literal>EXISTS</literal> tests in the form
21793 <literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
21794 this rule however, such as subqueries that use <token>INTERSECT</token>.
21795 </para>
21797 <para>
21798 This simple example is like an inner join on <literal>col2</literal>, but
21799 it produces at most one output row for each <literal>tab1</literal> row,
21800 even if there are several matching <literal>tab2</literal> rows:
21801 <screen>
21802 SELECT col1
21803 FROM tab1
21804 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
21805 </screen>
21806 </para>
21807 </sect2>
21809 <sect2 id="functions-subquery-in">
21810 <title><literal>IN</literal></title>
21812 <synopsis>
21813 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
21814 </synopsis>
21816 <para>
21817 The right-hand side is a parenthesized
21818 subquery, which must return exactly one column. The left-hand expression
21819 is evaluated and compared to each row of the subquery result.
21820 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
21821 The result is <quote>false</quote> if no equal row is found (including the
21822 case where the subquery returns no rows).
21823 </para>
21825 <para>
21826 Note that if the left-hand expression yields null, or if there are
21827 no equal right-hand values and at least one right-hand row yields
21828 null, the result of the <token>IN</token> construct will be null, not false.
21829 This is in accordance with SQL's normal rules for Boolean combinations
21830 of null values.
21831 </para>
21833 <para>
21834 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
21835 be evaluated completely.
21836 </para>
21838 <synopsis>
21839 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
21840 </synopsis>
21842 <para>
21843 The left-hand side of this form of <token>IN</token> is a row constructor,
21844 as described in <xref linkend="sql-syntax-row-constructors"/>.
21845 The right-hand side is a parenthesized
21846 subquery, which must return exactly as many columns as there are
21847 expressions in the left-hand row. The left-hand expressions are
21848 evaluated and compared row-wise to each row of the subquery result.
21849 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
21850 The result is <quote>false</quote> if no equal row is found (including the
21851 case where the subquery returns no rows).
21852 </para>
21854 <para>
21855 As usual, null values in the rows are combined per
21856 the normal rules of SQL Boolean expressions. Two rows are considered
21857 equal if all their corresponding members are non-null and equal; the rows
21858 are unequal if any corresponding members are non-null and unequal;
21859 otherwise the result of that row comparison is unknown (null).
21860 If all the per-row results are either unequal or null, with at least one
21861 null, then the result of <token>IN</token> is null.
21862 </para>
21863 </sect2>
21865 <sect2 id="functions-subquery-notin">
21866 <title><literal>NOT IN</literal></title>
21868 <synopsis>
21869 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
21870 </synopsis>
21872 <para>
21873 The right-hand side is a parenthesized
21874 subquery, which must return exactly one column. The left-hand expression
21875 is evaluated and compared to each row of the subquery result.
21876 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
21877 are found (including the case where the subquery returns no rows).
21878 The result is <quote>false</quote> if any equal row is found.
21879 </para>
21881 <para>
21882 Note that if the left-hand expression yields null, or if there are
21883 no equal right-hand values and at least one right-hand row yields
21884 null, the result of the <token>NOT IN</token> construct will be null, not true.
21885 This is in accordance with SQL's normal rules for Boolean combinations
21886 of null values.
21887 </para>
21889 <para>
21890 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
21891 be evaluated completely.
21892 </para>
21894 <synopsis>
21895 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
21896 </synopsis>
21898 <para>
21899 The left-hand side of this form of <token>NOT IN</token> is a row constructor,
21900 as described in <xref linkend="sql-syntax-row-constructors"/>.
21901 The right-hand side is a parenthesized
21902 subquery, which must return exactly as many columns as there are
21903 expressions in the left-hand row. The left-hand expressions are
21904 evaluated and compared row-wise to each row of the subquery result.
21905 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
21906 are found (including the case where the subquery returns no rows).
21907 The result is <quote>false</quote> if any equal row is found.
21908 </para>
21910 <para>
21911 As usual, null values in the rows are combined per
21912 the normal rules of SQL Boolean expressions. Two rows are considered
21913 equal if all their corresponding members are non-null and equal; the rows
21914 are unequal if any corresponding members are non-null and unequal;
21915 otherwise the result of that row comparison is unknown (null).
21916 If all the per-row results are either unequal or null, with at least one
21917 null, then the result of <token>NOT IN</token> is null.
21918 </para>
21919 </sect2>
21921 <sect2 id="functions-subquery-any-some">
21922 <title><literal>ANY</literal>/<literal>SOME</literal></title>
21924 <synopsis>
21925 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
21926 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
21927 </synopsis>
21929 <para>
21930 The right-hand side is a parenthesized
21931 subquery, which must return exactly one column. The left-hand expression
21932 is evaluated and compared to each row of the subquery result using the
21933 given <replaceable>operator</replaceable>, which must yield a Boolean
21934 result.
21935 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
21936 The result is <quote>false</quote> if no true result is found (including the
21937 case where the subquery returns no rows).
21938 </para>
21940 <para>
21941 <token>SOME</token> is a synonym for <token>ANY</token>.
21942 <token>IN</token> is equivalent to <literal>= ANY</literal>.
21943 </para>
21945 <para>
21946 Note that if there are no successes and at least one right-hand row yields
21947 null for the operator's result, the result of the <token>ANY</token> construct
21948 will be null, not false.
21949 This is in accordance with SQL's normal rules for Boolean combinations
21950 of null values.
21951 </para>
21953 <para>
21954 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
21955 be evaluated completely.
21956 </para>
21958 <synopsis>
21959 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
21960 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
21961 </synopsis>
21963 <para>
21964 The left-hand side of this form of <token>ANY</token> is a row constructor,
21965 as described in <xref linkend="sql-syntax-row-constructors"/>.
21966 The right-hand side is a parenthesized
21967 subquery, which must return exactly as many columns as there are
21968 expressions in the left-hand row. The left-hand expressions are
21969 evaluated and compared row-wise to each row of the subquery result,
21970 using the given <replaceable>operator</replaceable>.
21971 The result of <token>ANY</token> is <quote>true</quote> if the comparison
21972 returns true for any subquery row.
21973 The result is <quote>false</quote> if the comparison returns false for every
21974 subquery row (including the case where the subquery returns no
21975 rows).
21976 The result is NULL if no comparison with a subquery row returns true,
21977 and at least one comparison returns NULL.
21978 </para>
21980 <para>
21981 See <xref linkend="row-wise-comparison"/> for details about the meaning
21982 of a row constructor comparison.
21983 </para>
21984 </sect2>
21986 <sect2 id="functions-subquery-all">
21987 <title><literal>ALL</literal></title>
21989 <synopsis>
21990 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
21991 </synopsis>
21993 <para>
21994 The right-hand side is a parenthesized
21995 subquery, which must return exactly one column. The left-hand expression
21996 is evaluated and compared to each row of the subquery result using the
21997 given <replaceable>operator</replaceable>, which must yield a Boolean
21998 result.
21999 The result of <token>ALL</token> is <quote>true</quote> if all rows yield true
22000 (including the case where the subquery returns no rows).
22001 The result is <quote>false</quote> if any false result is found.
22002 The result is NULL if no comparison with a subquery row returns false,
22003 and at least one comparison returns NULL.
22004 </para>
22006 <para>
22007 <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
22008 </para>
22010 <para>
22011 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22012 be evaluated completely.
22013 </para>
22015 <synopsis>
22016 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
22017 </synopsis>
22019 <para>
22020 The left-hand side of this form of <token>ALL</token> is a row constructor,
22021 as described in <xref linkend="sql-syntax-row-constructors"/>.
22022 The right-hand side is a parenthesized
22023 subquery, which must return exactly as many columns as there are
22024 expressions in the left-hand row. The left-hand expressions are
22025 evaluated and compared row-wise to each row of the subquery result,
22026 using the given <replaceable>operator</replaceable>.
22027 The result of <token>ALL</token> is <quote>true</quote> if the comparison
22028 returns true for all subquery rows (including the
22029 case where the subquery returns no rows).
22030 The result is <quote>false</quote> if the comparison returns false for any
22031 subquery row.
22032 The result is NULL if no comparison with a subquery row returns false,
22033 and at least one comparison returns NULL.
22034 </para>
22036 <para>
22037 See <xref linkend="row-wise-comparison"/> for details about the meaning
22038 of a row constructor comparison.
22039 </para>
22040 </sect2>
22042 <sect2 id="functions-subquery-single-row-comp">
22043 <title>Single-Row Comparison</title>
22045 <indexterm zone="functions-subquery">
22046 <primary>comparison</primary>
22047 <secondary>subquery result row</secondary>
22048 </indexterm>
22050 <synopsis>
22051 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
22052 </synopsis>
22054 <para>
22055 The left-hand side is a row constructor,
22056 as described in <xref linkend="sql-syntax-row-constructors"/>.
22057 The right-hand side is a parenthesized subquery, which must return exactly
22058 as many columns as there are expressions in the left-hand row. Furthermore,
22059 the subquery cannot return more than one row. (If it returns zero rows,
22060 the result is taken to be null.) The left-hand side is evaluated and
22061 compared row-wise to the single subquery result row.
22062 </para>
22064 <para>
22065 See <xref linkend="row-wise-comparison"/> for details about the meaning
22066 of a row constructor comparison.
22067 </para>
22068 </sect2>
22069 </sect1>
22072 <sect1 id="functions-comparisons">
22073 <title>Row and Array Comparisons</title>
22075 <indexterm>
22076 <primary>IN</primary>
22077 </indexterm>
22079 <indexterm>
22080 <primary>NOT IN</primary>
22081 </indexterm>
22083 <indexterm>
22084 <primary>ANY</primary>
22085 </indexterm>
22087 <indexterm>
22088 <primary>ALL</primary>
22089 </indexterm>
22091 <indexterm>
22092 <primary>SOME</primary>
22093 </indexterm>
22095 <indexterm>
22096 <primary>composite type</primary>
22097 <secondary>comparison</secondary>
22098 </indexterm>
22100 <indexterm>
22101 <primary>row-wise comparison</primary>
22102 </indexterm>
22104 <indexterm>
22105 <primary>comparison</primary>
22106 <secondary>composite type</secondary>
22107 </indexterm>
22109 <indexterm>
22110 <primary>comparison</primary>
22111 <secondary>row constructor</secondary>
22112 </indexterm>
22114 <indexterm>
22115 <primary>IS DISTINCT FROM</primary>
22116 </indexterm>
22118 <indexterm>
22119 <primary>IS NOT DISTINCT FROM</primary>
22120 </indexterm>
22122 <para>
22123 This section describes several specialized constructs for making
22124 multiple comparisons between groups of values. These forms are
22125 syntactically related to the subquery forms of the previous section,
22126 but do not involve subqueries.
22127 The forms involving array subexpressions are
22128 <productname>PostgreSQL</productname> extensions; the rest are
22129 <acronym>SQL</acronym>-compliant.
22130 All of the expression forms documented in this section return
22131 Boolean (true/false) results.
22132 </para>
22134 <sect2 id="functions-comparisons-in-scalar">
22135 <title><literal>IN</literal></title>
22137 <synopsis>
22138 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
22139 </synopsis>
22141 <para>
22142 The right-hand side is a parenthesized list
22143 of expressions. The result is <quote>true</quote> if the left-hand expression's
22144 result is equal to any of the right-hand expressions. This is a shorthand
22145 notation for
22147 <synopsis>
22148 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
22150 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
22153 </synopsis>
22154 </para>
22156 <para>
22157 Note that if the left-hand expression yields null, or if there are
22158 no equal right-hand values and at least one right-hand expression yields
22159 null, the result of the <token>IN</token> construct will be null, not false.
22160 This is in accordance with SQL's normal rules for Boolean combinations
22161 of null values.
22162 </para>
22163 </sect2>
22165 <sect2 id="functions-comparisons-not-in">
22166 <title><literal>NOT IN</literal></title>
22168 <synopsis>
22169 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
22170 </synopsis>
22172 <para>
22173 The right-hand side is a parenthesized list
22174 of expressions. The result is <quote>true</quote> if the left-hand expression's
22175 result is unequal to all of the right-hand expressions. This is a shorthand
22176 notation for
22178 <synopsis>
22179 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
22181 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
22184 </synopsis>
22185 </para>
22187 <para>
22188 Note that if the left-hand expression yields null, or if there are
22189 no equal right-hand values and at least one right-hand expression yields
22190 null, the result of the <token>NOT IN</token> construct will be null, not true
22191 as one might naively expect.
22192 This is in accordance with SQL's normal rules for Boolean combinations
22193 of null values.
22194 </para>
22196 <tip>
22197 <para>
22198 <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
22199 cases. However, null values are much more likely to trip up the novice when
22200 working with <token>NOT IN</token> than when working with <token>IN</token>.
22201 It is best to express your condition positively if possible.
22202 </para>
22203 </tip>
22204 </sect2>
22206 <sect2 id="functions-comparisons-any-some">
22207 <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
22209 <synopsis>
22210 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
22211 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
22212 </synopsis>
22214 <para>
22215 The right-hand side is a parenthesized expression, which must yield an
22216 array value.
22217 The left-hand expression
22218 is evaluated and compared to each element of the array using the
22219 given <replaceable>operator</replaceable>, which must yield a Boolean
22220 result.
22221 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
22222 The result is <quote>false</quote> if no true result is found (including the
22223 case where the array has zero elements).
22224 </para>
22226 <para>
22227 If the array expression yields a null array, the result of
22228 <token>ANY</token> will be null. If the left-hand expression yields null,
22229 the result of <token>ANY</token> is ordinarily null (though a non-strict
22230 comparison operator could possibly yield a different result).
22231 Also, if the right-hand array contains any null elements and no true
22232 comparison result is obtained, the result of <token>ANY</token>
22233 will be null, not false (again, assuming a strict comparison operator).
22234 This is in accordance with SQL's normal rules for Boolean combinations
22235 of null values.
22236 </para>
22238 <para>
22239 <token>SOME</token> is a synonym for <token>ANY</token>.
22240 </para>
22241 </sect2>
22243 <sect2 id="functions-comparisons-all">
22244 <title><literal>ALL</literal> (array)</title>
22246 <synopsis>
22247 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
22248 </synopsis>
22250 <para>
22251 The right-hand side is a parenthesized expression, which must yield an
22252 array value.
22253 The left-hand expression
22254 is evaluated and compared to each element of the array using the
22255 given <replaceable>operator</replaceable>, which must yield a Boolean
22256 result.
22257 The result of <token>ALL</token> is <quote>true</quote> if all comparisons yield true
22258 (including the case where the array has zero elements).
22259 The result is <quote>false</quote> if any false result is found.
22260 </para>
22262 <para>
22263 If the array expression yields a null array, the result of
22264 <token>ALL</token> will be null. If the left-hand expression yields null,
22265 the result of <token>ALL</token> is ordinarily null (though a non-strict
22266 comparison operator could possibly yield a different result).
22267 Also, if the right-hand array contains any null elements and no false
22268 comparison result is obtained, the result of <token>ALL</token>
22269 will be null, not true (again, assuming a strict comparison operator).
22270 This is in accordance with SQL's normal rules for Boolean combinations
22271 of null values.
22272 </para>
22273 </sect2>
22275 <sect2 id="row-wise-comparison">
22276 <title>Row Constructor Comparison</title>
22278 <synopsis>
22279 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
22280 </synopsis>
22282 <para>
22283 Each side is a row constructor,
22284 as described in <xref linkend="sql-syntax-row-constructors"/>.
22285 The two row constructors must have the same number of fields.
22286 The given <replaceable>operator</replaceable> is applied to each pair
22287 of corresponding fields. (Since the fields could be of different
22288 types, this means that a different specific operator could be selected
22289 for each pair.)
22290 All the selected operators must be members of some B-tree operator
22291 class, or be the negator of an <literal>=</literal> member of a B-tree
22292 operator class, meaning that row constructor comparison is only
22293 possible when the <replaceable>operator</replaceable> is
22294 <literal>=</literal>,
22295 <literal>&lt;&gt;</literal>,
22296 <literal>&lt;</literal>,
22297 <literal>&lt;=</literal>,
22298 <literal>&gt;</literal>, or
22299 <literal>&gt;=</literal>,
22300 or has semantics similar to one of these.
22301 </para>
22303 <para>
22304 The <literal>=</literal> and <literal>&lt;&gt;</literal> cases work slightly differently
22305 from the others. Two rows are considered
22306 equal if all their corresponding members are non-null and equal; the rows
22307 are unequal if any corresponding members are non-null and unequal;
22308 otherwise the result of the row comparison is unknown (null).
22309 </para>
22311 <para>
22312 For the <literal>&lt;</literal>, <literal>&lt;=</literal>, <literal>&gt;</literal> and
22313 <literal>&gt;=</literal> cases, the row elements are compared left-to-right,
22314 stopping as soon as an unequal or null pair of elements is found.
22315 If either of this pair of elements is null, the result of the
22316 row comparison is unknown (null); otherwise comparison of this pair
22317 of elements determines the result. For example,
22318 <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</literal>
22319 yields true, not null, because the third pair of elements are not
22320 considered.
22321 </para>
22323 <synopsis>
22324 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
22325 </synopsis>
22327 <para>
22328 This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
22329 but it does not yield null for null inputs. Instead, any null value is
22330 considered unequal to (distinct from) any non-null value, and any two
22331 nulls are considered equal (not distinct). Thus the result will
22332 either be true or false, never null.
22333 </para>
22335 <synopsis>
22336 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
22337 </synopsis>
22339 <para>
22340 This construct is similar to a <literal>=</literal> row comparison,
22341 but it does not yield null for null inputs. Instead, any null value is
22342 considered unequal to (distinct from) any non-null value, and any two
22343 nulls are considered equal (not distinct). Thus the result will always
22344 be either true or false, never null.
22345 </para>
22347 </sect2>
22349 <sect2 id="composite-type-comparison">
22350 <title>Composite Type Comparison</title>
22352 <synopsis>
22353 <replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
22354 </synopsis>
22356 <para>
22357 The SQL specification requires row-wise comparison to return NULL if the
22358 result depends on comparing two NULL values or a NULL and a non-NULL.
22359 <productname>PostgreSQL</productname> does this only when comparing the
22360 results of two row constructors (as in
22361 <xref linkend="row-wise-comparison"/>) or comparing a row constructor
22362 to the output of a subquery (as in <xref linkend="functions-subquery"/>).
22363 In other contexts where two composite-type values are compared, two
22364 NULL field values are considered equal, and a NULL is considered larger
22365 than a non-NULL. This is necessary in order to have consistent sorting
22366 and indexing behavior for composite types.
22367 </para>
22369 <para>
22370 Each side is evaluated and they are compared row-wise. Composite type
22371 comparisons are allowed when the <replaceable>operator</replaceable> is
22372 <literal>=</literal>,
22373 <literal>&lt;&gt;</literal>,
22374 <literal>&lt;</literal>,
22375 <literal>&lt;=</literal>,
22376 <literal>&gt;</literal> or
22377 <literal>&gt;=</literal>,
22378 or has semantics similar to one of these. (To be specific, an operator
22379 can be a row comparison operator if it is a member of a B-tree operator
22380 class, or is the negator of the <literal>=</literal> member of a B-tree operator
22381 class.) The default behavior of the above operators is the same as for
22382 <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
22383 <xref linkend="row-wise-comparison"/>).
22384 </para>
22386 <para>
22387 To support matching of rows which include elements without a default
22388 B-tree operator class, the following operators are defined for composite
22389 type comparison:
22390 <literal>*=</literal>,
22391 <literal>*&lt;&gt;</literal>,
22392 <literal>*&lt;</literal>,
22393 <literal>*&lt;=</literal>,
22394 <literal>*&gt;</literal>, and
22395 <literal>*&gt;=</literal>.
22396 These operators compare the internal binary representation of the two
22397 rows. Two rows might have a different binary representation even
22398 though comparisons of the two rows with the equality operator is true.
22399 The ordering of rows under these comparison operators is deterministic
22400 but not otherwise meaningful. These operators are used internally
22401 for materialized views and might be useful for other specialized
22402 purposes such as replication and B-Tree deduplication (see <xref
22403 linkend="btree-deduplication"/>). They are not intended to be
22404 generally useful for writing queries, though.
22405 </para>
22406 </sect2>
22407 </sect1>
22409 <sect1 id="functions-srf">
22410 <title>Set Returning Functions</title>
22412 <indexterm zone="functions-srf">
22413 <primary>set returning functions</primary>
22414 <secondary>functions</secondary>
22415 </indexterm>
22417 <para>
22418 This section describes functions that possibly return more than one row.
22419 The most widely used functions in this class are series generating
22420 functions, as detailed in <xref linkend="functions-srf-series"/> and
22421 <xref linkend="functions-srf-subscripts"/>. Other, more specialized
22422 set-returning functions are described elsewhere in this manual.
22423 See <xref linkend="queries-tablefunctions"/> for ways to combine multiple
22424 set-returning functions.
22425 </para>
22427 <table id="functions-srf-series">
22428 <title>Series Generating Functions</title>
22429 <tgroup cols="1">
22430 <thead>
22431 <row>
22432 <entry role="func_table_entry"><para role="func_signature">
22433 Function
22434 </para>
22435 <para>
22436 Description
22437 </para></entry>
22438 </row>
22439 </thead>
22441 <tbody>
22442 <row>
22443 <entry role="func_table_entry"><para role="func_signature">
22444 <indexterm>
22445 <primary>generate_series</primary>
22446 </indexterm>
22447 <function>generate_series</function> ( <parameter>start</parameter> <type>integer</type>, <parameter>stop</parameter> <type>integer</type> <optional>, <parameter>step</parameter> <type>integer</type> </optional> )
22448 <returnvalue>setof integer</returnvalue>
22449 </para>
22450 <para role="func_signature">
22451 <function>generate_series</function> ( <parameter>start</parameter> <type>bigint</type>, <parameter>stop</parameter> <type>bigint</type> <optional>, <parameter>step</parameter> <type>bigint</type> </optional> )
22452 <returnvalue>setof bigint</returnvalue>
22453 </para>
22454 <para role="func_signature">
22455 <function>generate_series</function> ( <parameter>start</parameter> <type>numeric</type>, <parameter>stop</parameter> <type>numeric</type> <optional>, <parameter>step</parameter> <type>numeric</type> </optional> )
22456 <returnvalue>setof numeric</returnvalue>
22457 </para>
22458 <para>
22459 Generates a series of values from <parameter>start</parameter>
22460 to <parameter>stop</parameter>, with a step size
22461 of <parameter>step</parameter>. <parameter>step</parameter>
22462 defaults to 1.
22463 </para></entry>
22464 </row>
22466 <row>
22467 <entry role="func_table_entry"><para role="func_signature">
22468 <function>generate_series</function> ( <parameter>start</parameter> <type>timestamp</type>, <parameter>stop</parameter> <type>timestamp</type>, <parameter>step</parameter> <type>interval</type> )
22469 <returnvalue>setof timestamp</returnvalue>
22470 </para>
22471 <para role="func_signature">
22472 <function>generate_series</function> ( <parameter>start</parameter> <type>timestamp with time zone</type>, <parameter>stop</parameter> <type>timestamp with time zone</type>, <parameter>step</parameter> <type>interval</type> <optional>, <parameter>timezone</parameter> <type>text</type> </optional> )
22473 <returnvalue>setof timestamp with time zone</returnvalue>
22474 </para>
22475 <para>
22476 Generates a series of values from <parameter>start</parameter>
22477 to <parameter>stop</parameter>, with a step size
22478 of <parameter>step</parameter>.
22479 In the timezone-aware form, times of day and daylight-savings
22480 adjustments are computed according to the time zone named by
22481 the <parameter>timezone</parameter> argument, or the current
22482 <xref linkend="guc-timezone"/> setting if that is omitted.
22483 </para></entry>
22484 </row>
22485 </tbody>
22486 </tgroup>
22487 </table>
22489 <para>
22490 When <parameter>step</parameter> is positive, zero rows are returned if
22491 <parameter>start</parameter> is greater than <parameter>stop</parameter>.
22492 Conversely, when <parameter>step</parameter> is negative, zero rows are
22493 returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
22494 Zero rows are also returned if any input is <literal>NULL</literal>.
22495 It is an error
22496 for <parameter>step</parameter> to be zero. Some examples follow:
22497 <programlisting>
22498 SELECT * FROM generate_series(2,4);
22499 generate_series
22500 -----------------
22504 (3 rows)
22506 SELECT * FROM generate_series(5,1,-2);
22507 generate_series
22508 -----------------
22512 (3 rows)
22514 SELECT * FROM generate_series(4,3);
22515 generate_series
22516 -----------------
22517 (0 rows)
22519 SELECT generate_series(1.1, 4, 1.3);
22520 generate_series
22521 -----------------
22525 (3 rows)
22527 -- this example relies on the date-plus-integer operator:
22528 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
22529 dates
22530 ------------
22531 2004-02-05
22532 2004-02-12
22533 2004-02-19
22534 (3 rows)
22536 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
22537 '2008-03-04 12:00', '10 hours');
22538 generate_series
22539 ---------------------
22540 2008-03-01 00:00:00
22541 2008-03-01 10:00:00
22542 2008-03-01 20:00:00
22543 2008-03-02 06:00:00
22544 2008-03-02 16:00:00
22545 2008-03-03 02:00:00
22546 2008-03-03 12:00:00
22547 2008-03-03 22:00:00
22548 2008-03-04 08:00:00
22549 (9 rows)
22551 -- this example assumes that TimeZone is set to UTC; note the DST transition:
22552 SELECT * FROM generate_series('2001-10-22 00:00 -04:00'::timestamptz,
22553 '2001-11-01 00:00 -05:00'::timestamptz,
22554 '1 day'::interval, 'America/New_York');
22555 generate_series
22556 ------------------------
22557 2001-10-22 04:00:00+00
22558 2001-10-23 04:00:00+00
22559 2001-10-24 04:00:00+00
22560 2001-10-25 04:00:00+00
22561 2001-10-26 04:00:00+00
22562 2001-10-27 04:00:00+00
22563 2001-10-28 04:00:00+00
22564 2001-10-29 05:00:00+00
22565 2001-10-30 05:00:00+00
22566 2001-10-31 05:00:00+00
22567 2001-11-01 05:00:00+00
22568 (11 rows)
22569 </programlisting>
22570 </para>
22572 <table id="functions-srf-subscripts">
22573 <title>Subscript Generating Functions</title>
22574 <tgroup cols="1">
22575 <thead>
22576 <row>
22577 <entry role="func_table_entry"><para role="func_signature">
22578 Function
22579 </para>
22580 <para>
22581 Description
22582 </para></entry>
22583 </row>
22584 </thead>
22586 <tbody>
22587 <row>
22588 <entry role="func_table_entry"><para role="func_signature">
22589 <indexterm>
22590 <primary>generate_subscripts</primary>
22591 </indexterm>
22592 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type> )
22593 <returnvalue>setof integer</returnvalue>
22594 </para>
22595 <para>
22596 Generates a series comprising the valid subscripts of
22597 the <parameter>dim</parameter>'th dimension of the given array.
22598 </para></entry>
22599 </row>
22601 <row>
22602 <entry role="func_table_entry"><para role="func_signature">
22603 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type>, <parameter>reverse</parameter> <type>boolean</type> )
22604 <returnvalue>setof integer</returnvalue>
22605 </para>
22606 <para>
22607 Generates a series comprising the valid subscripts of
22608 the <parameter>dim</parameter>'th dimension of the given array.
22609 When <parameter>reverse</parameter> is true, returns the series in
22610 reverse order.
22611 </para></entry>
22612 </row>
22613 </tbody>
22614 </tgroup>
22615 </table>
22617 <para>
22618 <function>generate_subscripts</function> is a convenience function that generates
22619 the set of valid subscripts for the specified dimension of the given
22620 array.
22621 Zero rows are returned for arrays that do not have the requested dimension,
22622 or if any input is <literal>NULL</literal>.
22623 Some examples follow:
22624 <programlisting>
22625 -- basic usage:
22626 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
22633 (4 rows)
22635 -- presenting an array, the subscript and the subscripted
22636 -- value requires a subquery:
22637 SELECT * FROM arrays;
22639 --------------------
22640 {-1,-2}
22641 {100,200,300}
22642 (2 rows)
22644 SELECT a AS array, s AS subscript, a[s] AS value
22645 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
22646 array | subscript | value
22647 ---------------+-----------+-------
22648 {-1,-2} | 1 | -1
22649 {-1,-2} | 2 | -2
22650 {100,200,300} | 1 | 100
22651 {100,200,300} | 2 | 200
22652 {100,200,300} | 3 | 300
22653 (5 rows)
22655 -- unnest a 2D array:
22656 CREATE OR REPLACE FUNCTION unnest2(anyarray)
22657 RETURNS SETOF anyelement AS $$
22658 select $1[i][j]
22659 from generate_subscripts($1,1) g1(i),
22660 generate_subscripts($1,2) g2(j);
22661 $$ LANGUAGE sql IMMUTABLE;
22662 CREATE FUNCTION
22663 SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
22664 unnest2
22665 ---------
22670 (4 rows)
22671 </programlisting>
22672 </para>
22674 <indexterm>
22675 <primary>ordinality</primary>
22676 </indexterm>
22678 <para>
22679 When a function in the <literal>FROM</literal> clause is suffixed
22680 by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is
22681 appended to the function's output column(s), which starts from 1 and
22682 increments by 1 for each row of the function's output.
22683 This is most useful in the case of set returning
22684 functions such as <function>unnest()</function>.
22686 <programlisting>
22687 -- set returning function WITH ORDINALITY:
22688 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
22689 ls | n
22690 -----------------+----
22691 pg_serial | 1
22692 pg_twophase | 2
22693 postmaster.opts | 3
22694 pg_notify | 4
22695 postgresql.conf | 5
22696 pg_tblspc | 6
22697 logfile | 7
22698 base | 8
22699 postmaster.pid | 9
22700 pg_ident.conf | 10
22701 global | 11
22702 pg_xact | 12
22703 pg_snapshots | 13
22704 pg_multixact | 14
22705 PG_VERSION | 15
22706 pg_wal | 16
22707 pg_hba.conf | 17
22708 pg_stat_tmp | 18
22709 pg_subtrans | 19
22710 (19 rows)
22711 </programlisting>
22712 </para>
22714 </sect1>
22716 <sect1 id="functions-info">
22717 <title>System Information Functions and Operators</title>
22719 <para>
22720 The functions described in this section are used to obtain various
22721 information about a <productname>PostgreSQL</productname> installation.
22722 </para>
22724 <sect2 id="functions-info-session">
22725 <title>Session Information Functions</title>
22727 <para>
22728 <xref linkend="functions-info-session-table"/> shows several
22729 functions that extract session and system information.
22730 </para>
22732 <para>
22733 In addition to the functions listed in this section, there are a number of
22734 functions related to the statistics system that also provide system
22735 information. See <xref linkend="monitoring-stats-functions"/> for more
22736 information.
22737 </para>
22739 <table id="functions-info-session-table">
22740 <title>Session Information Functions</title>
22741 <tgroup cols="1">
22742 <thead>
22743 <row>
22744 <entry role="func_table_entry"><para role="func_signature">
22745 Function
22746 </para>
22747 <para>
22748 Description
22749 </para></entry>
22750 </row>
22751 </thead>
22753 <tbody>
22754 <row>
22755 <entry role="func_table_entry"><para role="func_signature">
22756 <indexterm>
22757 <primary>current_catalog</primary>
22758 </indexterm>
22759 <function>current_catalog</function>
22760 <returnvalue>name</returnvalue>
22761 </para>
22762 <para role="func_signature">
22763 <indexterm>
22764 <primary>current_database</primary>
22765 </indexterm>
22766 <function>current_database</function> ()
22767 <returnvalue>name</returnvalue>
22768 </para>
22769 <para>
22770 Returns the name of the current database. (Databases are
22771 called <quote>catalogs</quote> in the SQL standard,
22772 so <function>current_catalog</function> is the standard's
22773 spelling.)
22774 </para></entry>
22775 </row>
22777 <row>
22778 <entry role="func_table_entry"><para role="func_signature">
22779 <indexterm>
22780 <primary>current_query</primary>
22781 </indexterm>
22782 <function>current_query</function> ()
22783 <returnvalue>text</returnvalue>
22784 </para>
22785 <para>
22786 Returns the text of the currently executing query, as submitted
22787 by the client (which might contain more than one statement).
22788 </para></entry>
22789 </row>
22791 <row>
22792 <entry role="func_table_entry"><para role="func_signature">
22793 <indexterm>
22794 <primary>current_role</primary>
22795 </indexterm>
22796 <function>current_role</function>
22797 <returnvalue>name</returnvalue>
22798 </para>
22799 <para>
22800 This is equivalent to <function>current_user</function>.
22801 </para></entry>
22802 </row>
22804 <row>
22805 <entry role="func_table_entry"><para role="func_signature">
22806 <indexterm>
22807 <primary>current_schema</primary>
22808 </indexterm>
22809 <indexterm>
22810 <primary>schema</primary>
22811 <secondary>current</secondary>
22812 </indexterm>
22813 <function>current_schema</function>
22814 <returnvalue>name</returnvalue>
22815 </para>
22816 <para role="func_signature">
22817 <function>current_schema</function> ()
22818 <returnvalue>name</returnvalue>
22819 </para>
22820 <para>
22821 Returns the name of the schema that is first in the search path (or a
22822 null value if the search path is empty). This is the schema that will
22823 be used for any tables or other named objects that are created without
22824 specifying a target schema.
22825 </para></entry>
22826 </row>
22828 <row>
22829 <entry role="func_table_entry"><para role="func_signature">
22830 <indexterm>
22831 <primary>current_schemas</primary>
22832 </indexterm>
22833 <indexterm>
22834 <primary>search path</primary>
22835 <secondary>current</secondary>
22836 </indexterm>
22837 <function>current_schemas</function> ( <parameter>include_implicit</parameter> <type>boolean</type> )
22838 <returnvalue>name[]</returnvalue>
22839 </para>
22840 <para>
22841 Returns an array of the names of all schemas presently in the
22842 effective search path, in their priority order. (Items in the current
22843 <xref linkend="guc-search-path"/> setting that do not correspond to
22844 existing, searchable schemas are omitted.) If the Boolean argument
22845 is <literal>true</literal>, then implicitly-searched system schemas
22846 such as <literal>pg_catalog</literal> are included in the result.
22847 </para></entry>
22848 </row>
22850 <row>
22851 <entry role="func_table_entry"><para role="func_signature">
22852 <indexterm>
22853 <primary>current_user</primary>
22854 </indexterm>
22855 <indexterm>
22856 <primary>user</primary>
22857 <secondary>current</secondary>
22858 </indexterm>
22859 <function>current_user</function>
22860 <returnvalue>name</returnvalue>
22861 </para>
22862 <para>
22863 Returns the user name of the current execution context.
22864 </para></entry>
22865 </row>
22867 <row>
22868 <entry role="func_table_entry"><para role="func_signature">
22869 <indexterm>
22870 <primary>inet_client_addr</primary>
22871 </indexterm>
22872 <function>inet_client_addr</function> ()
22873 <returnvalue>inet</returnvalue>
22874 </para>
22875 <para>
22876 Returns the IP address of the current client,
22877 or <literal>NULL</literal> if the current connection is via a
22878 Unix-domain socket.
22879 </para></entry>
22880 </row>
22882 <row>
22883 <entry role="func_table_entry"><para role="func_signature">
22884 <indexterm>
22885 <primary>inet_client_port</primary>
22886 </indexterm>
22887 <function>inet_client_port</function> ()
22888 <returnvalue>integer</returnvalue>
22889 </para>
22890 <para>
22891 Returns the IP port number of the current client,
22892 or <literal>NULL</literal> if the current connection is via a
22893 Unix-domain socket.
22894 </para></entry>
22895 </row>
22897 <row>
22898 <entry role="func_table_entry"><para role="func_signature">
22899 <indexterm>
22900 <primary>inet_server_addr</primary>
22901 </indexterm>
22902 <function>inet_server_addr</function> ()
22903 <returnvalue>inet</returnvalue>
22904 </para>
22905 <para>
22906 Returns the IP address on which the server accepted the current
22907 connection,
22908 or <literal>NULL</literal> if the current connection is via a
22909 Unix-domain socket.
22910 </para></entry>
22911 </row>
22913 <row>
22914 <entry role="func_table_entry"><para role="func_signature">
22915 <indexterm>
22916 <primary>inet_server_port</primary>
22917 </indexterm>
22918 <function>inet_server_port</function> ()
22919 <returnvalue>integer</returnvalue>
22920 </para>
22921 <para>
22922 Returns the IP port number on which the server accepted the current
22923 connection,
22924 or <literal>NULL</literal> if the current connection is via a
22925 Unix-domain socket.
22926 </para></entry>
22927 </row>
22929 <row>
22930 <entry role="func_table_entry"><para role="func_signature">
22931 <indexterm>
22932 <primary>pg_backend_pid</primary>
22933 </indexterm>
22934 <function>pg_backend_pid</function> ()
22935 <returnvalue>integer</returnvalue>
22936 </para>
22937 <para>
22938 Returns the process ID of the server process attached to the current
22939 session.
22940 </para></entry>
22941 </row>
22943 <row>
22944 <entry role="func_table_entry"><para role="func_signature">
22945 <indexterm>
22946 <primary>pg_blocking_pids</primary>
22947 </indexterm>
22948 <function>pg_blocking_pids</function> ( <type>integer</type> )
22949 <returnvalue>integer[]</returnvalue>
22950 </para>
22951 <para>
22952 Returns an array of the process ID(s) of the sessions that are
22953 blocking the server process with the specified process ID from
22954 acquiring a lock, or an empty array if there is no such server process
22955 or it is not blocked.
22956 </para>
22957 <para>
22958 One server process blocks another if it either holds a lock that
22959 conflicts with the blocked process's lock request (hard block), or is
22960 waiting for a lock that would conflict with the blocked process's lock
22961 request and is ahead of it in the wait queue (soft block). When using
22962 parallel queries the result always lists client-visible process IDs
22963 (that is, <function>pg_backend_pid</function> results) even if the
22964 actual lock is held or awaited by a child worker process. As a result
22965 of that, there may be duplicated PIDs in the result. Also note that
22966 when a prepared transaction holds a conflicting lock, it will be
22967 represented by a zero process ID.
22968 </para>
22969 <para>
22970 Frequent calls to this function could have some impact on database
22971 performance, because it needs exclusive access to the lock manager's
22972 shared state for a short time.
22973 </para></entry>
22974 </row>
22976 <row>
22977 <entry role="func_table_entry"><para role="func_signature">
22978 <indexterm>
22979 <primary>pg_conf_load_time</primary>
22980 </indexterm>
22981 <function>pg_conf_load_time</function> ()
22982 <returnvalue>timestamp with time zone</returnvalue>
22983 </para>
22984 <para>
22985 Returns the time when the server configuration files were last loaded.
22986 If the current session was alive at the time, this will be the time
22987 when the session itself re-read the configuration files (so the
22988 reading will vary a little in different sessions). Otherwise it is
22989 the time when the postmaster process re-read the configuration files.
22990 </para></entry>
22991 </row>
22993 <row>
22994 <entry role="func_table_entry"><para role="func_signature">
22995 <indexterm>
22996 <primary>pg_current_logfile</primary>
22997 </indexterm>
22998 <indexterm>
22999 <primary>Logging</primary>
23000 <secondary>pg_current_logfile function</secondary>
23001 </indexterm>
23002 <indexterm>
23003 <primary>current_logfiles</primary>
23004 <secondary>and the pg_current_logfile function</secondary>
23005 </indexterm>
23006 <indexterm>
23007 <primary>Logging</primary>
23008 <secondary>current_logfiles file and the pg_current_logfile
23009 function</secondary>
23010 </indexterm>
23011 <function>pg_current_logfile</function> ( <optional> <type>text</type> </optional> )
23012 <returnvalue>text</returnvalue>
23013 </para>
23014 <para>
23015 Returns the path name of the log file currently in use by the logging
23016 collector. The path includes the <xref linkend="guc-log-directory"/>
23017 directory and the individual log file name. The result
23018 is <literal>NULL</literal> if the logging collector is disabled.
23019 When multiple log files exist, each in a different
23020 format, <function>pg_current_logfile</function> without an argument
23021 returns the path of the file having the first format found in the
23022 ordered list: <literal>stderr</literal>,
23023 <literal>csvlog</literal>, <literal>jsonlog</literal>.
23024 <literal>NULL</literal> is returned if no log file has any of these
23025 formats.
23026 To request information about a specific log file format, supply
23027 either <literal>csvlog</literal>, <literal>jsonlog</literal> or
23028 <literal>stderr</literal> as the
23029 value of the optional parameter. The result is <literal>NULL</literal>
23030 if the log format requested is not configured in
23031 <xref linkend="guc-log-destination"/>.
23032 The result reflects the contents of
23033 the <filename>current_logfiles</filename> file.
23034 </para></entry>
23035 </row>
23037 <row>
23038 <entry role="func_table_entry"><para role="func_signature">
23039 <indexterm>
23040 <primary>pg_my_temp_schema</primary>
23041 </indexterm>
23042 <function>pg_my_temp_schema</function> ()
23043 <returnvalue>oid</returnvalue>
23044 </para>
23045 <para>
23046 Returns the OID of the current session's temporary schema, or zero if
23047 it has none (because it has not created any temporary tables).
23048 </para></entry>
23049 </row>
23051 <row>
23052 <entry role="func_table_entry"><para role="func_signature">
23053 <indexterm>
23054 <primary>pg_is_other_temp_schema</primary>
23055 </indexterm>
23056 <function>pg_is_other_temp_schema</function> ( <type>oid</type> )
23057 <returnvalue>boolean</returnvalue>
23058 </para>
23059 <para>
23060 Returns true if the given OID is the OID of another session's
23061 temporary schema. (This can be useful, for example, to exclude other
23062 sessions' temporary tables from a catalog display.)
23063 </para></entry>
23064 </row>
23066 <row>
23067 <entry role="func_table_entry"><para role="func_signature">
23068 <indexterm>
23069 <primary>pg_jit_available</primary>
23070 </indexterm>
23071 <function>pg_jit_available</function> ()
23072 <returnvalue>boolean</returnvalue>
23073 </para>
23074 <para>
23075 Returns true if a <acronym>JIT</acronym> compiler extension is
23076 available (see <xref linkend="jit"/>) and the
23077 <xref linkend="guc-jit"/> configuration parameter is set to
23078 <literal>on</literal>.
23079 </para></entry>
23080 </row>
23082 <row>
23083 <entry role="func_table_entry"><para role="func_signature">
23084 <indexterm>
23085 <primary>pg_listening_channels</primary>
23086 </indexterm>
23087 <function>pg_listening_channels</function> ()
23088 <returnvalue>setof text</returnvalue>
23089 </para>
23090 <para>
23091 Returns the set of names of asynchronous notification channels that
23092 the current session is listening to.
23093 </para></entry>
23094 </row>
23096 <row>
23097 <entry role="func_table_entry"><para role="func_signature">
23098 <indexterm>
23099 <primary>pg_notification_queue_usage</primary>
23100 </indexterm>
23101 <function>pg_notification_queue_usage</function> ()
23102 <returnvalue>double precision</returnvalue>
23103 </para>
23104 <para>
23105 Returns the fraction (0&ndash;1) of the asynchronous notification
23106 queue's maximum size that is currently occupied by notifications that
23107 are waiting to be processed.
23108 See <xref linkend="sql-listen"/> and <xref linkend="sql-notify"/>
23109 for more information.
23110 </para></entry>
23111 </row>
23113 <row>
23114 <entry role="func_table_entry"><para role="func_signature">
23115 <indexterm>
23116 <primary>pg_postmaster_start_time</primary>
23117 </indexterm>
23118 <function>pg_postmaster_start_time</function> ()
23119 <returnvalue>timestamp with time zone</returnvalue>
23120 </para>
23121 <para>
23122 Returns the time when the server started.
23123 </para></entry>
23124 </row>
23126 <row>
23127 <entry role="func_table_entry"><para role="func_signature">
23128 <indexterm>
23129 <primary>pg_safe_snapshot_blocking_pids</primary>
23130 </indexterm>
23131 <function>pg_safe_snapshot_blocking_pids</function> ( <type>integer</type> )
23132 <returnvalue>integer[]</returnvalue>
23133 </para>
23134 <para>
23135 Returns an array of the process ID(s) of the sessions that are blocking
23136 the server process with the specified process ID from acquiring a safe
23137 snapshot, or an empty array if there is no such server process or it
23138 is not blocked.
23139 </para>
23140 <para>
23141 A session running a <literal>SERIALIZABLE</literal> transaction blocks
23142 a <literal>SERIALIZABLE READ ONLY DEFERRABLE</literal> transaction
23143 from acquiring a snapshot until the latter determines that it is safe
23144 to avoid taking any predicate locks. See
23145 <xref linkend="xact-serializable"/> for more information about
23146 serializable and deferrable transactions.
23147 </para>
23148 <para>
23149 Frequent calls to this function could have some impact on database
23150 performance, because it needs access to the predicate lock manager's
23151 shared state for a short time.
23152 </para></entry>
23153 </row>
23155 <row>
23156 <entry role="func_table_entry"><para role="func_signature">
23157 <indexterm>
23158 <primary>pg_trigger_depth</primary>
23159 </indexterm>
23160 <function>pg_trigger_depth</function> ()
23161 <returnvalue>integer</returnvalue>
23162 </para>
23163 <para>
23164 Returns the current nesting level
23165 of <productname>PostgreSQL</productname> triggers (0 if not called,
23166 directly or indirectly, from inside a trigger).
23167 </para></entry>
23168 </row>
23170 <row>
23171 <entry role="func_table_entry"><para role="func_signature">
23172 <indexterm>
23173 <primary>session_user</primary>
23174 </indexterm>
23175 <function>session_user</function>
23176 <returnvalue>name</returnvalue>
23177 </para>
23178 <para>
23179 Returns the session user's name.
23180 </para></entry>
23181 </row>
23183 <row>
23184 <entry role="func_table_entry"><para role="func_signature">
23185 <indexterm>
23186 <primary>system_user</primary>
23187 </indexterm>
23188 <function>system_user</function>
23189 <returnvalue>text</returnvalue>
23190 </para>
23191 <para>
23192 Returns the authentication method and the identity (if any) that the
23193 user presented during the authentication cycle before they were
23194 assigned a database role. It is represented as
23195 <literal>auth_method:identity</literal> or
23196 <literal>NULL</literal> if the user has not been authenticated (for
23197 example if <link linkend="auth-trust">Trust authentication</link> has
23198 been used).
23199 </para></entry>
23200 </row>
23202 <row>
23203 <entry role="func_table_entry"><para role="func_signature">
23204 <indexterm>
23205 <primary>user</primary>
23206 </indexterm>
23207 <function>user</function>
23208 <returnvalue>name</returnvalue>
23209 </para>
23210 <para>
23211 This is equivalent to <function>current_user</function>.
23212 </para></entry>
23213 </row>
23215 <row>
23216 <entry role="func_table_entry"><para role="func_signature">
23217 <indexterm>
23218 <primary>version</primary>
23219 </indexterm>
23220 <function>version</function> ()
23221 <returnvalue>text</returnvalue>
23222 </para>
23223 <para>
23224 Returns a string describing the <productname>PostgreSQL</productname>
23225 server's version. You can also get this information from
23226 <xref linkend="guc-server-version"/>, or for a machine-readable
23227 version use <xref linkend="guc-server-version-num"/>. Software
23228 developers should use <varname>server_version_num</varname> (available
23229 since 8.2) or <xref linkend="libpq-PQserverVersion"/> instead of
23230 parsing the text version.
23231 </para></entry>
23232 </row>
23233 </tbody>
23234 </tgroup>
23235 </table>
23237 <note>
23238 <para>
23239 <function>current_catalog</function>,
23240 <function>current_role</function>,
23241 <function>current_schema</function>,
23242 <function>current_user</function>,
23243 <function>session_user</function>,
23244 and <function>user</function> have special syntactic status
23245 in <acronym>SQL</acronym>: they must be called without trailing
23246 parentheses. In PostgreSQL, parentheses can optionally be used with
23247 <function>current_schema</function>, but not with the others.
23248 </para>
23249 </note>
23251 <para>
23252 The <function>session_user</function> is normally the user who initiated
23253 the current database connection; but superusers can change this setting
23254 with <xref linkend="sql-set-session-authorization"/>.
23255 The <function>current_user</function> is the user identifier
23256 that is applicable for permission checking. Normally it is equal
23257 to the session user, but it can be changed with
23258 <xref linkend="sql-set-role"/>.
23259 It also changes during the execution of
23260 functions with the attribute <literal>SECURITY DEFINER</literal>.
23261 In Unix parlance, the session user is the <quote>real user</quote> and
23262 the current user is the <quote>effective user</quote>.
23263 <function>current_role</function> and <function>user</function> are
23264 synonyms for <function>current_user</function>. (The SQL standard draws
23265 a distinction between <function>current_role</function>
23266 and <function>current_user</function>, but <productname>PostgreSQL</productname>
23267 does not, since it unifies users and roles into a single kind of entity.)
23268 </para>
23270 </sect2>
23272 <sect2 id="functions-info-access">
23273 <title>Access Privilege Inquiry Functions</title>
23275 <indexterm>
23276 <primary>privilege</primary>
23277 <secondary>querying</secondary>
23278 </indexterm>
23280 <para>
23281 <xref linkend="functions-info-access-table"/> lists functions that
23282 allow querying object access privileges programmatically.
23283 (See <xref linkend="ddl-priv"/> for more information about
23284 privileges.)
23285 In these functions, the user whose privileges are being inquired about
23286 can be specified by name or by OID
23287 (<structname>pg_authid</structname>.<structfield>oid</structfield>), or if
23288 the name is given as <literal>public</literal> then the privileges of the
23289 PUBLIC pseudo-role are checked. Also, the <parameter>user</parameter>
23290 argument can be omitted entirely, in which case
23291 the <function>current_user</function> is assumed.
23292 The object that is being inquired about can be specified either by name or
23293 by OID, too. When specifying by name, a schema name can be included if
23294 relevant.
23295 The access privilege of interest is specified by a text string, which must
23296 evaluate to one of the appropriate privilege keywords for the object's type
23297 (e.g., <literal>SELECT</literal>). Optionally, <literal>WITH GRANT
23298 OPTION</literal> can be added to a privilege type to test whether the
23299 privilege is held with grant option. Also, multiple privilege types can be
23300 listed separated by commas, in which case the result will be true if any of
23301 the listed privileges is held. (Case of the privilege string is not
23302 significant, and extra whitespace is allowed between but not within
23303 privilege names.)
23304 Some examples:
23305 <programlisting>
23306 SELECT has_table_privilege('myschema.mytable', 'select');
23307 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
23308 </programlisting>
23309 </para>
23311 <table id="functions-info-access-table">
23312 <title>Access Privilege Inquiry Functions</title>
23313 <tgroup cols="1">
23314 <thead>
23315 <row>
23316 <entry role="func_table_entry"><para role="func_signature">
23317 Function
23318 </para>
23319 <para>
23320 Description
23321 </para></entry>
23322 </row>
23323 </thead>
23325 <tbody>
23326 <row>
23327 <entry role="func_table_entry"><para role="func_signature">
23328 <indexterm>
23329 <primary>has_any_column_privilege</primary>
23330 </indexterm>
23331 <function>has_any_column_privilege</function> (
23332 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23333 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
23334 <parameter>privilege</parameter> <type>text</type> )
23335 <returnvalue>boolean</returnvalue>
23336 </para>
23337 <para>
23338 Does user have privilege for any column of table?
23339 This succeeds either if the privilege is held for the whole table, or
23340 if there is a column-level grant of the privilege for at least one
23341 column.
23342 Allowable privilege types are
23343 <literal>SELECT</literal>, <literal>INSERT</literal>,
23344 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
23345 </para></entry>
23346 </row>
23348 <row>
23349 <entry role="func_table_entry"><para role="func_signature">
23350 <indexterm>
23351 <primary>has_column_privilege</primary>
23352 </indexterm>
23353 <function>has_column_privilege</function> (
23354 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23355 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
23356 <parameter>column</parameter> <type>text</type> or <type>smallint</type>,
23357 <parameter>privilege</parameter> <type>text</type> )
23358 <returnvalue>boolean</returnvalue>
23359 </para>
23360 <para>
23361 Does user have privilege for the specified table column?
23362 This succeeds either if the privilege is held for the whole table, or
23363 if there is a column-level grant of the privilege for the column.
23364 The column can be specified by name or by attribute number
23365 (<structname>pg_attribute</structname>.<structfield>attnum</structfield>).
23366 Allowable privilege types are
23367 <literal>SELECT</literal>, <literal>INSERT</literal>,
23368 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
23369 </para></entry>
23370 </row>
23372 <row>
23373 <entry role="func_table_entry"><para role="func_signature">
23374 <indexterm>
23375 <primary>has_database_privilege</primary>
23376 </indexterm>
23377 <function>has_database_privilege</function> (
23378 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23379 <parameter>database</parameter> <type>text</type> or <type>oid</type>,
23380 <parameter>privilege</parameter> <type>text</type> )
23381 <returnvalue>boolean</returnvalue>
23382 </para>
23383 <para>
23384 Does user have privilege for database?
23385 Allowable privilege types are
23386 <literal>CREATE</literal>,
23387 <literal>CONNECT</literal>,
23388 <literal>TEMPORARY</literal>, and
23389 <literal>TEMP</literal> (which is equivalent to
23390 <literal>TEMPORARY</literal>).
23391 </para></entry>
23392 </row>
23394 <row>
23395 <entry role="func_table_entry"><para role="func_signature">
23396 <indexterm>
23397 <primary>has_foreign_data_wrapper_privilege</primary>
23398 </indexterm>
23399 <function>has_foreign_data_wrapper_privilege</function> (
23400 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23401 <parameter>fdw</parameter> <type>text</type> or <type>oid</type>,
23402 <parameter>privilege</parameter> <type>text</type> )
23403 <returnvalue>boolean</returnvalue>
23404 </para>
23405 <para>
23406 Does user have privilege for foreign-data wrapper?
23407 The only allowable privilege type is <literal>USAGE</literal>.
23408 </para></entry>
23409 </row>
23411 <row>
23412 <entry role="func_table_entry"><para role="func_signature">
23413 <indexterm>
23414 <primary>has_function_privilege</primary>
23415 </indexterm>
23416 <function>has_function_privilege</function> (
23417 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23418 <parameter>function</parameter> <type>text</type> or <type>oid</type>,
23419 <parameter>privilege</parameter> <type>text</type> )
23420 <returnvalue>boolean</returnvalue>
23421 </para>
23422 <para>
23423 Does user have privilege for function?
23424 The only allowable privilege type is <literal>EXECUTE</literal>.
23425 </para>
23426 <para>
23427 When specifying a function by name rather than by OID, the allowed
23428 input is the same as for the <type>regprocedure</type> data type (see
23429 <xref linkend="datatype-oid"/>).
23430 An example is:
23431 <programlisting>
23432 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
23433 </programlisting>
23434 </para></entry>
23435 </row>
23437 <row>
23438 <entry role="func_table_entry"><para role="func_signature">
23439 <indexterm>
23440 <primary>has_language_privilege</primary>
23441 </indexterm>
23442 <function>has_language_privilege</function> (
23443 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23444 <parameter>language</parameter> <type>text</type> or <type>oid</type>,
23445 <parameter>privilege</parameter> <type>text</type> )
23446 <returnvalue>boolean</returnvalue>
23447 </para>
23448 <para>
23449 Does user have privilege for language?
23450 The only allowable privilege type is <literal>USAGE</literal>.
23451 </para></entry>
23452 </row>
23454 <row>
23455 <entry role="func_table_entry"><para role="func_signature">
23456 <indexterm>
23457 <primary>has_parameter_privilege</primary>
23458 </indexterm>
23459 <function>has_parameter_privilege</function> (
23460 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23461 <parameter>parameter</parameter> <type>text</type>,
23462 <parameter>privilege</parameter> <type>text</type> )
23463 <returnvalue>boolean</returnvalue>
23464 </para>
23465 <para>
23466 Does user have privilege for configuration parameter?
23467 The parameter name is case-insensitive.
23468 Allowable privilege types are <literal>SET</literal>
23469 and <literal>ALTER SYSTEM</literal>.
23470 </para></entry>
23471 </row>
23473 <row>
23474 <entry role="func_table_entry"><para role="func_signature">
23475 <indexterm>
23476 <primary>has_schema_privilege</primary>
23477 </indexterm>
23478 <function>has_schema_privilege</function> (
23479 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23480 <parameter>schema</parameter> <type>text</type> or <type>oid</type>,
23481 <parameter>privilege</parameter> <type>text</type> )
23482 <returnvalue>boolean</returnvalue>
23483 </para>
23484 <para>
23485 Does user have privilege for schema?
23486 Allowable privilege types are
23487 <literal>CREATE</literal> and
23488 <literal>USAGE</literal>.
23489 </para></entry>
23490 </row>
23492 <row>
23493 <entry role="func_table_entry"><para role="func_signature">
23494 <indexterm>
23495 <primary>has_sequence_privilege</primary>
23496 </indexterm>
23497 <function>has_sequence_privilege</function> (
23498 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23499 <parameter>sequence</parameter> <type>text</type> or <type>oid</type>,
23500 <parameter>privilege</parameter> <type>text</type> )
23501 <returnvalue>boolean</returnvalue>
23502 </para>
23503 <para>
23504 Does user have privilege for sequence?
23505 Allowable privilege types are
23506 <literal>USAGE</literal>,
23507 <literal>SELECT</literal>, and
23508 <literal>UPDATE</literal>.
23509 </para></entry>
23510 </row>
23512 <row>
23513 <entry role="func_table_entry"><para role="func_signature">
23514 <indexterm>
23515 <primary>has_server_privilege</primary>
23516 </indexterm>
23517 <function>has_server_privilege</function> (
23518 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23519 <parameter>server</parameter> <type>text</type> or <type>oid</type>,
23520 <parameter>privilege</parameter> <type>text</type> )
23521 <returnvalue>boolean</returnvalue>
23522 </para>
23523 <para>
23524 Does user have privilege for foreign server?
23525 The only allowable privilege type is <literal>USAGE</literal>.
23526 </para></entry>
23527 </row>
23529 <row>
23530 <entry role="func_table_entry"><para role="func_signature">
23531 <indexterm>
23532 <primary>has_table_privilege</primary>
23533 </indexterm>
23534 <function>has_table_privilege</function> (
23535 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23536 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
23537 <parameter>privilege</parameter> <type>text</type> )
23538 <returnvalue>boolean</returnvalue>
23539 </para>
23540 <para>
23541 Does user have privilege for table?
23542 Allowable privilege types
23543 are <literal>SELECT</literal>, <literal>INSERT</literal>,
23544 <literal>UPDATE</literal>, <literal>DELETE</literal>,
23545 <literal>TRUNCATE</literal>, <literal>REFERENCES</literal>,
23546 and <literal>TRIGGER</literal>.
23547 </para></entry>
23548 </row>
23550 <row>
23551 <entry role="func_table_entry"><para role="func_signature">
23552 <indexterm>
23553 <primary>has_tablespace_privilege</primary>
23554 </indexterm>
23555 <function>has_tablespace_privilege</function> (
23556 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23557 <parameter>tablespace</parameter> <type>text</type> or <type>oid</type>,
23558 <parameter>privilege</parameter> <type>text</type> )
23559 <returnvalue>boolean</returnvalue>
23560 </para>
23561 <para>
23562 Does user have privilege for tablespace?
23563 The only allowable privilege type is <literal>CREATE</literal>.
23564 </para></entry>
23565 </row>
23567 <row>
23568 <entry role="func_table_entry"><para role="func_signature">
23569 <indexterm>
23570 <primary>has_type_privilege</primary>
23571 </indexterm>
23572 <function>has_type_privilege</function> (
23573 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23574 <parameter>type</parameter> <type>text</type> or <type>oid</type>,
23575 <parameter>privilege</parameter> <type>text</type> )
23576 <returnvalue>boolean</returnvalue>
23577 </para>
23578 <para>
23579 Does user have privilege for data type?
23580 The only allowable privilege type is <literal>USAGE</literal>.
23581 When specifying a type by name rather than by OID, the allowed input
23582 is the same as for the <type>regtype</type> data type (see
23583 <xref linkend="datatype-oid"/>).
23584 </para></entry>
23585 </row>
23587 <row>
23588 <entry role="func_table_entry"><para role="func_signature">
23589 <indexterm>
23590 <primary>pg_has_role</primary>
23591 </indexterm>
23592 <function>pg_has_role</function> (
23593 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23594 <parameter>role</parameter> <type>text</type> or <type>oid</type>,
23595 <parameter>privilege</parameter> <type>text</type> )
23596 <returnvalue>boolean</returnvalue>
23597 </para>
23598 <para>
23599 Does user have privilege for role?
23600 Allowable privilege types are
23601 <literal>MEMBER</literal>, <literal>USAGE</literal>,
23602 and <literal>SET</literal>.
23603 <literal>MEMBER</literal> denotes direct or indirect membership in
23604 the role without regard to what specific privileges may be conferred.
23605 <literal>USAGE</literal> denotes whether the privileges of the role
23606 are immediately available without doing <command>SET ROLE</command>,
23607 while <literal>SET</literal> denotes whether it is possible to change
23608 to the role using the <literal>SET ROLE</literal> command.
23609 This function does not allow the special case of
23610 setting <parameter>user</parameter> to <literal>public</literal>,
23611 because the PUBLIC pseudo-role can never be a member of real roles.
23612 </para></entry>
23613 </row>
23615 <row>
23616 <entry role="func_table_entry"><para role="func_signature">
23617 <indexterm>
23618 <primary>row_security_active</primary>
23619 </indexterm>
23620 <function>row_security_active</function> (
23621 <parameter>table</parameter> <type>text</type> or <type>oid</type> )
23622 <returnvalue>boolean</returnvalue>
23623 </para>
23624 <para>
23625 Is row-level security active for the specified table in the context of
23626 the current user and current environment?
23627 </para></entry>
23628 </row>
23629 </tbody>
23630 </tgroup>
23631 </table>
23633 <para>
23634 <xref linkend="functions-aclitem-op-table"/> shows the operators
23635 available for the <type>aclitem</type> type, which is the catalog
23636 representation of access privileges. See <xref linkend="ddl-priv"/>
23637 for information about how to read access privilege values.
23638 </para>
23640 <table id="functions-aclitem-op-table">
23641 <title><type>aclitem</type> Operators</title>
23642 <tgroup cols="1">
23643 <thead>
23644 <row>
23645 <entry role="func_table_entry"><para role="func_signature">
23646 Operator
23647 </para>
23648 <para>
23649 Description
23650 </para>
23651 <para>
23652 Example(s)
23653 </para></entry>
23654 </row>
23655 </thead>
23657 <tbody>
23658 <row>
23659 <entry role="func_table_entry"><para role="func_signature">
23660 <indexterm>
23661 <primary>aclitemeq</primary>
23662 </indexterm>
23663 <type>aclitem</type> <literal>=</literal> <type>aclitem</type>
23664 <returnvalue>boolean</returnvalue>
23665 </para>
23666 <para>
23667 Are <type>aclitem</type>s equal? (Notice that
23668 type <type>aclitem</type> lacks the usual set of comparison
23669 operators; it has only equality. In turn, <type>aclitem</type>
23670 arrays can only be compared for equality.)
23671 </para>
23672 <para>
23673 <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem</literal>
23674 <returnvalue>f</returnvalue>
23675 </para></entry>
23676 </row>
23678 <row>
23679 <entry role="func_table_entry"><para role="func_signature">
23680 <indexterm>
23681 <primary>aclcontains</primary>
23682 </indexterm>
23683 <type>aclitem[]</type> <literal>@&gt;</literal> <type>aclitem</type>
23684 <returnvalue>boolean</returnvalue>
23685 </para>
23686 <para>
23687 Does array contain the specified privileges? (This is true if there
23688 is an array entry that matches the <type>aclitem</type>'s grantee and
23689 grantor, and has at least the specified set of privileges.)
23690 </para>
23691 <para>
23692 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @&gt; 'calvin=r*/hobbes'::aclitem</literal>
23693 <returnvalue>t</returnvalue>
23694 </para></entry>
23695 </row>
23697 <row>
23698 <entry role="func_table_entry"><para role="func_signature">
23699 <type>aclitem[]</type> <literal>~</literal> <type>aclitem</type>
23700 <returnvalue>boolean</returnvalue>
23701 </para>
23702 <para>
23703 This is a deprecated alias for <literal>@&gt;</literal>.
23704 </para>
23705 <para>
23706 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem</literal>
23707 <returnvalue>t</returnvalue>
23708 </para></entry>
23709 </row>
23710 </tbody>
23711 </tgroup>
23712 </table>
23714 <para>
23715 <xref linkend="functions-aclitem-fn-table"/> shows some additional
23716 functions to manage the <type>aclitem</type> type.
23717 </para>
23719 <table id="functions-aclitem-fn-table">
23720 <title><type>aclitem</type> Functions</title>
23721 <tgroup cols="1">
23722 <thead>
23723 <row>
23724 <entry role="func_table_entry"><para role="func_signature">
23725 Function
23726 </para>
23727 <para>
23728 Description
23729 </para></entry>
23730 </row>
23731 </thead>
23733 <tbody>
23734 <row>
23735 <entry role="func_table_entry"><para role="func_signature">
23736 <indexterm>
23737 <primary>acldefault</primary>
23738 </indexterm>
23739 <function>acldefault</function> (
23740 <parameter>type</parameter> <type>"char"</type>,
23741 <parameter>ownerId</parameter> <type>oid</type> )
23742 <returnvalue>aclitem[]</returnvalue>
23743 </para>
23744 <para>
23745 Constructs an <type>aclitem</type> array holding the default access
23746 privileges for an object of type <parameter>type</parameter> belonging
23747 to the role with OID <parameter>ownerId</parameter>. This represents
23748 the access privileges that will be assumed when an object's ACL entry
23749 is null. (The default access privileges are described in
23750 <xref linkend="ddl-priv"/>.)
23751 The <parameter>type</parameter> parameter must be one of
23752 'c' for <literal>COLUMN</literal>,
23753 'r' for <literal>TABLE</literal> and table-like objects,
23754 's' for <literal>SEQUENCE</literal>,
23755 'd' for <literal>DATABASE</literal>,
23756 'f' for <literal>FUNCTION</literal> or <literal>PROCEDURE</literal>,
23757 'l' for <literal>LANGUAGE</literal>,
23758 'L' for <literal>LARGE OBJECT</literal>,
23759 'n' for <literal>SCHEMA</literal>,
23760 'p' for <literal>PARAMETER</literal>,
23761 't' for <literal>TABLESPACE</literal>,
23762 'F' for <literal>FOREIGN DATA WRAPPER</literal>,
23763 'S' for <literal>FOREIGN SERVER</literal>,
23765 'T' for <literal>TYPE</literal> or <literal>DOMAIN</literal>.
23766 </para></entry>
23767 </row>
23769 <row>
23770 <entry role="func_table_entry"><para role="func_signature">
23771 <indexterm>
23772 <primary>aclexplode</primary>
23773 </indexterm>
23774 <function>aclexplode</function> ( <type>aclitem[]</type> )
23775 <returnvalue>setof record</returnvalue>
23776 ( <parameter>grantor</parameter> <type>oid</type>,
23777 <parameter>grantee</parameter> <type>oid</type>,
23778 <parameter>privilege_type</parameter> <type>text</type>,
23779 <parameter>is_grantable</parameter> <type>boolean</type> )
23780 </para>
23781 <para>
23782 Returns the <type>aclitem</type> array as a set of rows.
23783 If the grantee is the pseudo-role PUBLIC, it is represented by zero in
23784 the <parameter>grantee</parameter> column. Each granted privilege is
23785 represented as <literal>SELECT</literal>, <literal>INSERT</literal>,
23786 etc (see <xref linkend="privilege-abbrevs-table"/> for a full list).
23787 Note that each privilege is broken out as a separate row, so
23788 only one keyword appears in the <parameter>privilege_type</parameter>
23789 column.
23790 </para></entry>
23791 </row>
23793 <row>
23794 <entry role="func_table_entry"><para role="func_signature">
23795 <indexterm>
23796 <primary>makeaclitem</primary>
23797 </indexterm>
23798 <function>makeaclitem</function> (
23799 <parameter>grantee</parameter> <type>oid</type>,
23800 <parameter>grantor</parameter> <type>oid</type>,
23801 <parameter>privileges</parameter> <type>text</type>,
23802 <parameter>is_grantable</parameter> <type>boolean</type> )
23803 <returnvalue>aclitem</returnvalue>
23804 </para>
23805 <para>
23806 Constructs an <type>aclitem</type> with the given properties.
23807 <parameter>privileges</parameter> is a comma-separated list of
23808 privilege names such as <literal>SELECT</literal>,
23809 <literal>INSERT</literal>, etc, all of which are set in the
23810 result. (Case of the privilege string is not significant, and
23811 extra whitespace is allowed between but not within privilege
23812 names.)
23813 </para></entry>
23814 </row>
23815 </tbody>
23816 </tgroup>
23817 </table>
23819 </sect2>
23821 <sect2 id="functions-info-schema">
23822 <title>Schema Visibility Inquiry Functions</title>
23824 <para>
23825 <xref linkend="functions-info-schema-table"/> shows functions that
23826 determine whether a certain object is <firstterm>visible</firstterm> in the
23827 current schema search path.
23828 For example, a table is said to be visible if its
23829 containing schema is in the search path and no table of the same
23830 name appears earlier in the search path. This is equivalent to the
23831 statement that the table can be referenced by name without explicit
23832 schema qualification. Thus, to list the names of all visible tables:
23833 <programlisting>
23834 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
23835 </programlisting>
23836 For functions and operators, an object in the search path is said to be
23837 visible if there is no object of the same name <emphasis>and argument data
23838 type(s)</emphasis> earlier in the path. For operator classes and families,
23839 both the name and the associated index access method are considered.
23840 </para>
23842 <indexterm>
23843 <primary>search path</primary>
23844 <secondary>object visibility</secondary>
23845 </indexterm>
23847 <table id="functions-info-schema-table">
23848 <title>Schema Visibility Inquiry Functions</title>
23849 <tgroup cols="1">
23850 <thead>
23851 <row>
23852 <entry role="func_table_entry"><para role="func_signature">
23853 Function
23854 </para>
23855 <para>
23856 Description
23857 </para></entry>
23858 </row>
23859 </thead>
23861 <tbody>
23862 <row>
23863 <entry role="func_table_entry"><para role="func_signature">
23864 <indexterm>
23865 <primary>pg_collation_is_visible</primary>
23866 </indexterm>
23867 <function>pg_collation_is_visible</function> ( <parameter>collation</parameter> <type>oid</type> )
23868 <returnvalue>boolean</returnvalue>
23869 </para>
23870 <para>
23871 Is collation visible in search path?
23872 </para></entry>
23873 </row>
23875 <row>
23876 <entry role="func_table_entry"><para role="func_signature">
23877 <indexterm>
23878 <primary>pg_conversion_is_visible</primary>
23879 </indexterm>
23880 <function>pg_conversion_is_visible</function> ( <parameter>conversion</parameter> <type>oid</type> )
23881 <returnvalue>boolean</returnvalue>
23882 </para>
23883 <para>
23884 Is conversion visible in search path?
23885 </para></entry>
23886 </row>
23888 <row>
23889 <entry role="func_table_entry"><para role="func_signature">
23890 <indexterm>
23891 <primary>pg_function_is_visible</primary>
23892 </indexterm>
23893 <function>pg_function_is_visible</function> ( <parameter>function</parameter> <type>oid</type> )
23894 <returnvalue>boolean</returnvalue>
23895 </para>
23896 <para>
23897 Is function visible in search path?
23898 (This also works for procedures and aggregates.)
23899 </para></entry>
23900 </row>
23902 <row>
23903 <entry role="func_table_entry"><para role="func_signature">
23904 <indexterm>
23905 <primary>pg_opclass_is_visible</primary>
23906 </indexterm>
23907 <function>pg_opclass_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
23908 <returnvalue>boolean</returnvalue>
23909 </para>
23910 <para>
23911 Is operator class visible in search path?
23912 </para></entry>
23913 </row>
23915 <row>
23916 <entry role="func_table_entry"><para role="func_signature">
23917 <indexterm>
23918 <primary>pg_operator_is_visible</primary>
23919 </indexterm>
23920 <function>pg_operator_is_visible</function> ( <parameter>operator</parameter> <type>oid</type> )
23921 <returnvalue>boolean</returnvalue>
23922 </para>
23923 <para>
23924 Is operator visible in search path?
23925 </para></entry>
23926 </row>
23928 <row>
23929 <entry role="func_table_entry"><para role="func_signature">
23930 <indexterm>
23931 <primary>pg_opfamily_is_visible</primary>
23932 </indexterm>
23933 <function>pg_opfamily_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
23934 <returnvalue>boolean</returnvalue>
23935 </para>
23936 <para>
23937 Is operator family visible in search path?
23938 </para></entry>
23939 </row>
23941 <row>
23942 <entry role="func_table_entry"><para role="func_signature">
23943 <indexterm>
23944 <primary>pg_statistics_obj_is_visible</primary>
23945 </indexterm>
23946 <function>pg_statistics_obj_is_visible</function> ( <parameter>stat</parameter> <type>oid</type> )
23947 <returnvalue>boolean</returnvalue>
23948 </para>
23949 <para>
23950 Is statistics object visible in search path?
23951 </para></entry>
23952 </row>
23954 <row>
23955 <entry role="func_table_entry"><para role="func_signature">
23956 <indexterm>
23957 <primary>pg_table_is_visible</primary>
23958 </indexterm>
23959 <function>pg_table_is_visible</function> ( <parameter>table</parameter> <type>oid</type> )
23960 <returnvalue>boolean</returnvalue>
23961 </para>
23962 <para>
23963 Is table visible in search path?
23964 (This works for all types of relations, including views, materialized
23965 views, indexes, sequences and foreign tables.)
23966 </para></entry>
23967 </row>
23969 <row>
23970 <entry role="func_table_entry"><para role="func_signature">
23971 <indexterm>
23972 <primary>pg_ts_config_is_visible</primary>
23973 </indexterm>
23974 <function>pg_ts_config_is_visible</function> ( <parameter>config</parameter> <type>oid</type> )
23975 <returnvalue>boolean</returnvalue>
23976 </para>
23977 <para>
23978 Is text search configuration visible in search path?
23979 </para></entry>
23980 </row>
23982 <row>
23983 <entry role="func_table_entry"><para role="func_signature">
23984 <indexterm>
23985 <primary>pg_ts_dict_is_visible</primary>
23986 </indexterm>
23987 <function>pg_ts_dict_is_visible</function> ( <parameter>dict</parameter> <type>oid</type> )
23988 <returnvalue>boolean</returnvalue>
23989 </para>
23990 <para>
23991 Is text search dictionary visible in search path?
23992 </para></entry>
23993 </row>
23995 <row>
23996 <entry role="func_table_entry"><para role="func_signature">
23997 <indexterm>
23998 <primary>pg_ts_parser_is_visible</primary>
23999 </indexterm>
24000 <function>pg_ts_parser_is_visible</function> ( <parameter>parser</parameter> <type>oid</type> )
24001 <returnvalue>boolean</returnvalue>
24002 </para>
24003 <para>
24004 Is text search parser visible in search path?
24005 </para></entry>
24006 </row>
24008 <row>
24009 <entry role="func_table_entry"><para role="func_signature">
24010 <indexterm>
24011 <primary>pg_ts_template_is_visible</primary>
24012 </indexterm>
24013 <function>pg_ts_template_is_visible</function> ( <parameter>template</parameter> <type>oid</type> )
24014 <returnvalue>boolean</returnvalue>
24015 </para>
24016 <para>
24017 Is text search template visible in search path?
24018 </para></entry>
24019 </row>
24021 <row>
24022 <entry role="func_table_entry"><para role="func_signature">
24023 <indexterm>
24024 <primary>pg_type_is_visible</primary>
24025 </indexterm>
24026 <function>pg_type_is_visible</function> ( <parameter>type</parameter> <type>oid</type> )
24027 <returnvalue>boolean</returnvalue>
24028 </para>
24029 <para>
24030 Is type (or domain) visible in search path?
24031 </para></entry>
24032 </row>
24033 </tbody>
24034 </tgroup>
24035 </table>
24037 <para>
24038 All these functions require object OIDs to identify the object to be
24039 checked. If you want to test an object by name, it is convenient to use
24040 the OID alias types (<type>regclass</type>, <type>regtype</type>,
24041 <type>regprocedure</type>, <type>regoperator</type>, <type>regconfig</type>,
24042 or <type>regdictionary</type>),
24043 for example:
24044 <programlisting>
24045 SELECT pg_type_is_visible('myschema.widget'::regtype);
24046 </programlisting>
24047 Note that it would not make much sense to test a non-schema-qualified
24048 type name in this way &mdash; if the name can be recognized at all, it must be visible.
24049 </para>
24051 </sect2>
24053 <sect2 id="functions-info-catalog">
24054 <title>System Catalog Information Functions</title>
24056 <para>
24057 <xref linkend="functions-info-catalog-table"/> lists functions that
24058 extract information from the system catalogs.
24059 </para>
24061 <table id="functions-info-catalog-table">
24062 <title>System Catalog Information Functions</title>
24063 <tgroup cols="1">
24064 <thead>
24065 <row>
24066 <entry role="func_table_entry"><para role="func_signature">
24067 Function
24068 </para>
24069 <para>
24070 Description
24071 </para></entry>
24072 </row>
24073 </thead>
24075 <tbody>
24076 <row>
24077 <entry role="func_table_entry"><para role="func_signature">
24078 <indexterm>
24079 <primary>format_type</primary>
24080 </indexterm>
24081 <function>format_type</function> ( <parameter>type</parameter> <type>oid</type>, <parameter>typemod</parameter> <type>integer</type> )
24082 <returnvalue>text</returnvalue>
24083 </para>
24084 <para>
24085 Returns the SQL name for a data type that is identified by its type
24086 OID and possibly a type modifier. Pass NULL for the type modifier if
24087 no specific modifier is known.
24088 </para></entry>
24089 </row>
24091 <row>
24092 <entry id="pg-char-to-encoding" role="func_table_entry"><para role="func_signature">
24093 <indexterm>
24094 <primary>pg_char_to_encoding</primary>
24095 </indexterm>
24096 <function>pg_char_to_encoding</function> ( <parameter>encoding</parameter> <type>name</type> )
24097 <returnvalue>integer</returnvalue>
24098 </para>
24099 <para>
24100 Converts the supplied encoding name into an integer representing the
24101 internal identifier used in some system catalog tables.
24102 Returns <literal>-1</literal> if an unknown encoding name is provided.
24103 </para></entry>
24104 </row>
24106 <row>
24107 <entry id="pg-encoding-to-char" role="func_table_entry"><para role="func_signature">
24108 <indexterm>
24109 <primary>pg_encoding_to_char</primary>
24110 </indexterm>
24111 <function>pg_encoding_to_char</function> ( <parameter>encoding</parameter> <type>integer</type> )
24112 <returnvalue>name</returnvalue>
24113 </para>
24114 <para>
24115 Converts the integer used as the internal identifier of an encoding in some
24116 system catalog tables into a human-readable string.
24117 Returns an empty string if an invalid encoding number is provided.
24118 </para></entry>
24119 </row>
24121 <row>
24122 <entry role="func_table_entry"><para role="func_signature">
24123 <indexterm>
24124 <primary>pg_get_catalog_foreign_keys</primary>
24125 </indexterm>
24126 <function>pg_get_catalog_foreign_keys</function> ()
24127 <returnvalue>setof record</returnvalue>
24128 ( <parameter>fktable</parameter> <type>regclass</type>,
24129 <parameter>fkcols</parameter> <type>text[]</type>,
24130 <parameter>pktable</parameter> <type>regclass</type>,
24131 <parameter>pkcols</parameter> <type>text[]</type>,
24132 <parameter>is_array</parameter> <type>boolean</type>,
24133 <parameter>is_opt</parameter> <type>boolean</type> )
24134 </para>
24135 <para>
24136 Returns a set of records describing the foreign key relationships
24137 that exist within the <productname>PostgreSQL</productname> system
24138 catalogs.
24139 The <parameter>fktable</parameter> column contains the name of the
24140 referencing catalog, and the <parameter>fkcols</parameter> column
24141 contains the name(s) of the referencing column(s). Similarly,
24142 the <parameter>pktable</parameter> column contains the name of the
24143 referenced catalog, and the <parameter>pkcols</parameter> column
24144 contains the name(s) of the referenced column(s).
24145 If <parameter>is_array</parameter> is true, the last referencing
24146 column is an array, each of whose elements should match some entry
24147 in the referenced catalog.
24148 If <parameter>is_opt</parameter> is true, the referencing column(s)
24149 are allowed to contain zeroes instead of a valid reference.
24150 </para></entry>
24151 </row>
24153 <row>
24154 <entry role="func_table_entry"><para role="func_signature">
24155 <indexterm>
24156 <primary>pg_get_constraintdef</primary>
24157 </indexterm>
24158 <function>pg_get_constraintdef</function> ( <parameter>constraint</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24159 <returnvalue>text</returnvalue>
24160 </para>
24161 <para>
24162 Reconstructs the creating command for a constraint.
24163 (This is a decompiled reconstruction, not the original text
24164 of the command.)
24165 </para></entry>
24166 </row>
24168 <row>
24169 <entry role="func_table_entry"><para role="func_signature">
24170 <indexterm>
24171 <primary>pg_get_expr</primary>
24172 </indexterm>
24173 <function>pg_get_expr</function> ( <parameter>expr</parameter> <type>pg_node_tree</type>, <parameter>relation</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24174 <returnvalue>text</returnvalue>
24175 </para>
24176 <para>
24177 Decompiles the internal form of an expression stored in the system
24178 catalogs, such as the default value for a column. If the expression
24179 might contain Vars, specify the OID of the relation they refer to as
24180 the second parameter; if no Vars are expected, passing zero is
24181 sufficient.
24182 </para></entry>
24183 </row>
24185 <row>
24186 <entry role="func_table_entry"><para role="func_signature">
24187 <indexterm>
24188 <primary>pg_get_functiondef</primary>
24189 </indexterm>
24190 <function>pg_get_functiondef</function> ( <parameter>func</parameter> <type>oid</type> )
24191 <returnvalue>text</returnvalue>
24192 </para>
24193 <para>
24194 Reconstructs the creating command for a function or procedure.
24195 (This is a decompiled reconstruction, not the original text
24196 of the command.)
24197 The result is a complete <command>CREATE OR REPLACE FUNCTION</command>
24198 or <command>CREATE OR REPLACE PROCEDURE</command> statement.
24199 </para></entry>
24200 </row>
24202 <row>
24203 <entry role="func_table_entry"><para role="func_signature">
24204 <indexterm>
24205 <primary>pg_get_function_arguments</primary>
24206 </indexterm>
24207 <function>pg_get_function_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
24208 <returnvalue>text</returnvalue>
24209 </para>
24210 <para>
24211 Reconstructs the argument list of a function or procedure, in the form
24212 it would need to appear in within <command>CREATE FUNCTION</command>
24213 (including default values).
24214 </para></entry>
24215 </row>
24217 <row>
24218 <entry role="func_table_entry"><para role="func_signature">
24219 <indexterm>
24220 <primary>pg_get_function_identity_arguments</primary>
24221 </indexterm>
24222 <function>pg_get_function_identity_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
24223 <returnvalue>text</returnvalue>
24224 </para>
24225 <para>
24226 Reconstructs the argument list necessary to identify a function or
24227 procedure, in the form it would need to appear in within commands such
24228 as <command>ALTER FUNCTION</command>. This form omits default values.
24229 </para></entry>
24230 </row>
24232 <row>
24233 <entry role="func_table_entry"><para role="func_signature">
24234 <indexterm>
24235 <primary>pg_get_function_result</primary>
24236 </indexterm>
24237 <function>pg_get_function_result</function> ( <parameter>func</parameter> <type>oid</type> )
24238 <returnvalue>text</returnvalue>
24239 </para>
24240 <para>
24241 Reconstructs the <literal>RETURNS</literal> clause of a function, in
24242 the form it would need to appear in within <command>CREATE
24243 FUNCTION</command>. Returns <literal>NULL</literal> for a procedure.
24244 </para></entry>
24245 </row>
24247 <row>
24248 <entry role="func_table_entry"><para role="func_signature">
24249 <indexterm>
24250 <primary>pg_get_indexdef</primary>
24251 </indexterm>
24252 <function>pg_get_indexdef</function> ( <parameter>index</parameter> <type>oid</type> <optional>, <parameter>column</parameter> <type>integer</type>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24253 <returnvalue>text</returnvalue>
24254 </para>
24255 <para>
24256 Reconstructs the creating command for an index.
24257 (This is a decompiled reconstruction, not the original text
24258 of the command.) If <parameter>column</parameter> is supplied and is
24259 not zero, only the definition of that column is reconstructed.
24260 </para></entry>
24261 </row>
24263 <row>
24264 <entry role="func_table_entry"><para role="func_signature">
24265 <indexterm>
24266 <primary>pg_get_keywords</primary>
24267 </indexterm>
24268 <function>pg_get_keywords</function> ()
24269 <returnvalue>setof record</returnvalue>
24270 ( <parameter>word</parameter> <type>text</type>,
24271 <parameter>catcode</parameter> <type>"char"</type>,
24272 <parameter>barelabel</parameter> <type>boolean</type>,
24273 <parameter>catdesc</parameter> <type>text</type>,
24274 <parameter>baredesc</parameter> <type>text</type> )
24275 </para>
24276 <para>
24277 Returns a set of records describing the SQL keywords recognized by the
24278 server. The <parameter>word</parameter> column contains the
24279 keyword. The <parameter>catcode</parameter> column contains a
24280 category code: <literal>U</literal> for an unreserved
24281 keyword, <literal>C</literal> for a keyword that can be a column
24282 name, <literal>T</literal> for a keyword that can be a type or
24283 function name, or <literal>R</literal> for a fully reserved keyword.
24284 The <parameter>barelabel</parameter> column
24285 contains <literal>true</literal> if the keyword can be used as
24286 a <quote>bare</quote> column label in <command>SELECT</command> lists,
24287 or <literal>false</literal> if it can only be used
24288 after <literal>AS</literal>.
24289 The <parameter>catdesc</parameter> column contains a
24290 possibly-localized string describing the keyword's category.
24291 The <parameter>baredesc</parameter> column contains a
24292 possibly-localized string describing the keyword's column label status.
24293 </para></entry>
24294 </row>
24296 <row>
24297 <entry role="func_table_entry"><para role="func_signature">
24298 <indexterm>
24299 <primary>pg_get_partkeydef</primary>
24300 </indexterm>
24301 <function>pg_get_partkeydef</function> ( <parameter>table</parameter> <type>oid</type> )
24302 <returnvalue>text</returnvalue>
24303 </para>
24304 <para>
24305 Reconstructs the definition of a partitioned table's partition
24306 key, in the form it would have in the <literal>PARTITION
24307 BY</literal> clause of <command>CREATE TABLE</command>.
24308 (This is a decompiled reconstruction, not the original text
24309 of the command.)
24310 </para></entry>
24311 </row>
24313 <row>
24314 <entry role="func_table_entry"><para role="func_signature">
24315 <indexterm>
24316 <primary>pg_get_ruledef</primary>
24317 </indexterm>
24318 <function>pg_get_ruledef</function> ( <parameter>rule</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24319 <returnvalue>text</returnvalue>
24320 </para>
24321 <para>
24322 Reconstructs the creating command for a rule.
24323 (This is a decompiled reconstruction, not the original text
24324 of the command.)
24325 </para></entry>
24326 </row>
24328 <row>
24329 <entry role="func_table_entry"><para role="func_signature">
24330 <indexterm>
24331 <primary>pg_get_serial_sequence</primary>
24332 </indexterm>
24333 <function>pg_get_serial_sequence</function> ( <parameter>table</parameter> <type>text</type>, <parameter>column</parameter> <type>text</type> )
24334 <returnvalue>text</returnvalue>
24335 </para>
24336 <para>
24337 Returns the name of the sequence associated with a column,
24338 or NULL if no sequence is associated with the column.
24339 If the column is an identity column, the associated sequence is the
24340 sequence internally created for that column.
24341 For columns created using one of the serial types
24342 (<type>serial</type>, <type>smallserial</type>, <type>bigserial</type>),
24343 it is the sequence created for that serial column definition.
24344 In the latter case, the association can be modified or removed
24345 with <command>ALTER SEQUENCE OWNED BY</command>.
24346 (This function probably should have been
24347 called <function>pg_get_owned_sequence</function>; its current name
24348 reflects the fact that it has historically been used with serial-type
24349 columns.) The first parameter is a table name with optional
24350 schema, and the second parameter is a column name. Because the first
24351 parameter potentially contains both schema and table names, it is
24352 parsed per usual SQL rules, meaning it is lower-cased by default.
24353 The second parameter, being just a column name, is treated literally
24354 and so has its case preserved. The result is suitably formatted
24355 for passing to the sequence functions (see
24356 <xref linkend="functions-sequence"/>).
24357 </para>
24358 <para>
24359 A typical use is in reading the current value of the sequence for an
24360 identity or serial column, for example:
24361 <programlisting>
24362 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
24363 </programlisting>
24364 </para></entry>
24365 </row>
24367 <row>
24368 <entry role="func_table_entry"><para role="func_signature">
24369 <indexterm>
24370 <primary>pg_get_statisticsobjdef</primary>
24371 </indexterm>
24372 <function>pg_get_statisticsobjdef</function> ( <parameter>statobj</parameter> <type>oid</type> )
24373 <returnvalue>text</returnvalue>
24374 </para>
24375 <para>
24376 Reconstructs the creating command for an extended statistics object.
24377 (This is a decompiled reconstruction, not the original text
24378 of the command.)
24379 </para></entry>
24380 </row>
24382 <row>
24383 <entry role="func_table_entry"><para role="func_signature">
24384 <indexterm>
24385 <primary>pg_get_triggerdef</primary>
24386 </indexterm>
24387 <function>pg_get_triggerdef</function> ( <parameter>trigger</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24388 <returnvalue>text</returnvalue>
24389 </para>
24390 <para>
24391 Reconstructs the creating command for a trigger.
24392 (This is a decompiled reconstruction, not the original text
24393 of the command.)
24394 </para></entry>
24395 </row>
24397 <row>
24398 <entry role="func_table_entry"><para role="func_signature">
24399 <indexterm>
24400 <primary>pg_get_userbyid</primary>
24401 </indexterm>
24402 <function>pg_get_userbyid</function> ( <parameter>role</parameter> <type>oid</type> )
24403 <returnvalue>name</returnvalue>
24404 </para>
24405 <para>
24406 Returns a role's name given its OID.
24407 </para></entry>
24408 </row>
24410 <row>
24411 <entry role="func_table_entry"><para role="func_signature">
24412 <indexterm>
24413 <primary>pg_get_viewdef</primary>
24414 </indexterm>
24415 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24416 <returnvalue>text</returnvalue>
24417 </para>
24418 <para>
24419 Reconstructs the underlying <command>SELECT</command> command for a
24420 view or materialized view. (This is a decompiled reconstruction, not
24421 the original text of the command.)
24422 </para></entry>
24423 </row>
24425 <row>
24426 <entry role="func_table_entry"><para role="func_signature">
24427 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type>, <parameter>wrap_column</parameter> <type>integer</type> )
24428 <returnvalue>text</returnvalue>
24429 </para>
24430 <para>
24431 Reconstructs the underlying <command>SELECT</command> command for a
24432 view or materialized view. (This is a decompiled reconstruction, not
24433 the original text of the command.) In this form of the function,
24434 pretty-printing is always enabled, and long lines are wrapped to try
24435 to keep them shorter than the specified number of columns.
24436 </para></entry>
24437 </row>
24439 <row>
24440 <entry role="func_table_entry"><para role="func_signature">
24441 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>text</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24442 <returnvalue>text</returnvalue>
24443 </para>
24444 <para>
24445 Reconstructs the underlying <command>SELECT</command> command for a
24446 view or materialized view, working from a textual name for the view
24447 rather than its OID. (This is deprecated; use the OID variant
24448 instead.)
24449 </para></entry>
24450 </row>
24452 <row>
24453 <entry role="func_table_entry"><para role="func_signature">
24454 <indexterm>
24455 <primary>pg_index_column_has_property</primary>
24456 </indexterm>
24457 <function>pg_index_column_has_property</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>column</parameter> <type>integer</type>, <parameter>property</parameter> <type>text</type> )
24458 <returnvalue>boolean</returnvalue>
24459 </para>
24460 <para>
24461 Tests whether an index column has the named property.
24462 Common index column properties are listed in
24463 <xref linkend="functions-info-index-column-props"/>.
24464 (Note that extension access methods can define additional property
24465 names for their indexes.)
24466 <literal>NULL</literal> is returned if the property name is not known
24467 or does not apply to the particular object, or if the OID or column
24468 number does not identify a valid object.
24469 </para></entry>
24470 </row>
24472 <row>
24473 <entry role="func_table_entry"><para role="func_signature">
24474 <indexterm>
24475 <primary>pg_index_has_property</primary>
24476 </indexterm>
24477 <function>pg_index_has_property</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>property</parameter> <type>text</type> )
24478 <returnvalue>boolean</returnvalue>
24479 </para>
24480 <para>
24481 Tests whether an index has the named property.
24482 Common index properties are listed in
24483 <xref linkend="functions-info-index-props"/>.
24484 (Note that extension access methods can define additional property
24485 names for their indexes.)
24486 <literal>NULL</literal> is returned if the property name is not known
24487 or does not apply to the particular object, or if the OID does not
24488 identify a valid object.
24489 </para></entry>
24490 </row>
24492 <row>
24493 <entry role="func_table_entry"><para role="func_signature">
24494 <indexterm>
24495 <primary>pg_indexam_has_property</primary>
24496 </indexterm>
24497 <function>pg_indexam_has_property</function> ( <parameter>am</parameter> <type>oid</type>, <parameter>property</parameter> <type>text</type> )
24498 <returnvalue>boolean</returnvalue>
24499 </para>
24500 <para>
24501 Tests whether an index access method has the named property.
24502 Access method properties are listed in
24503 <xref linkend="functions-info-indexam-props"/>.
24504 <literal>NULL</literal> is returned if the property name is not known
24505 or does not apply to the particular object, or if the OID does not
24506 identify a valid object.
24507 </para></entry>
24508 </row>
24510 <row>
24511 <entry role="func_table_entry"><para role="func_signature">
24512 <indexterm>
24513 <primary>pg_options_to_table</primary>
24514 </indexterm>
24515 <function>pg_options_to_table</function> ( <parameter>options_array</parameter> <type>text[]</type> )
24516 <returnvalue>setof record</returnvalue>
24517 ( <parameter>option_name</parameter> <type>text</type>,
24518 <parameter>option_value</parameter> <type>text</type> )
24519 </para>
24520 <para>
24521 Returns the set of storage options represented by a value from
24522 <structname>pg_class</structname>.<structfield>reloptions</structfield> or
24523 <structname>pg_attribute</structname>.<structfield>attoptions</structfield>.
24524 </para></entry>
24525 </row>
24527 <row>
24528 <entry role="func_table_entry"><para role="func_signature">
24529 <indexterm>
24530 <primary>pg_settings_get_flags</primary>
24531 </indexterm>
24532 <function>pg_settings_get_flags</function> ( <parameter>guc</parameter> <type>text</type> )
24533 <returnvalue>text[]</returnvalue>
24534 </para>
24535 <para>
24536 Returns an array of the flags associated with the given GUC, or
24537 <literal>NULL</literal> if it does not exist. The result is
24538 an empty array if the GUC exists but there are no flags to show.
24539 Only the most useful flags listed in
24540 <xref linkend="functions-pg-settings-flags"/> are exposed.
24541 </para></entry>
24542 </row>
24544 <row>
24545 <entry role="func_table_entry"><para role="func_signature">
24546 <indexterm>
24547 <primary>pg_tablespace_databases</primary>
24548 </indexterm>
24549 <function>pg_tablespace_databases</function> ( <parameter>tablespace</parameter> <type>oid</type> )
24550 <returnvalue>setof oid</returnvalue>
24551 </para>
24552 <para>
24553 Returns the set of OIDs of databases that have objects stored in the
24554 specified tablespace. If this function returns any rows, the
24555 tablespace is not empty and cannot be dropped. To identify the specific
24556 objects populating the tablespace, you will need to connect to the
24557 database(s) identified by <function>pg_tablespace_databases</function>
24558 and query their <structname>pg_class</structname> catalogs.
24559 </para></entry>
24560 </row>
24562 <row>
24563 <entry role="func_table_entry"><para role="func_signature">
24564 <indexterm>
24565 <primary>pg_tablespace_location</primary>
24566 </indexterm>
24567 <function>pg_tablespace_location</function> ( <parameter>tablespace</parameter> <type>oid</type> )
24568 <returnvalue>text</returnvalue>
24569 </para>
24570 <para>
24571 Returns the file system path that this tablespace is located in.
24572 </para></entry>
24573 </row>
24575 <row>
24576 <entry role="func_table_entry"><para role="func_signature">
24577 <indexterm>
24578 <primary>pg_typeof</primary>
24579 </indexterm>
24580 <function>pg_typeof</function> ( <type>"any"</type> )
24581 <returnvalue>regtype</returnvalue>
24582 </para>
24583 <para>
24584 Returns the OID of the data type of the value that is passed to it.
24585 This can be helpful for troubleshooting or dynamically constructing
24586 SQL queries. The function is declared as
24587 returning <type>regtype</type>, which is an OID alias type (see
24588 <xref linkend="datatype-oid"/>); this means that it is the same as an
24589 OID for comparison purposes but displays as a type name.
24590 </para>
24591 <para>
24592 For example:
24593 <programlisting>
24594 SELECT pg_typeof(33);
24595 pg_typeof
24596 -----------
24597 integer
24599 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
24600 typlen
24601 --------
24603 </programlisting>
24604 </para></entry>
24605 </row>
24607 <row>
24608 <entry role="func_table_entry"><para role="func_signature">
24609 <indexterm>
24610 <primary>COLLATION FOR</primary>
24611 </indexterm>
24612 <function>COLLATION FOR</function> ( <type>"any"</type> )
24613 <returnvalue>text</returnvalue>
24614 </para>
24615 <para>
24616 Returns the name of the collation of the value that is passed to it.
24617 The value is quoted and schema-qualified if necessary. If no
24618 collation was derived for the argument expression,
24619 then <literal>NULL</literal> is returned. If the argument is not of a
24620 collatable data type, then an error is raised.
24621 </para>
24622 <para>
24623 For example:
24624 <programlisting>
24625 SELECT collation for (description) FROM pg_description LIMIT 1;
24626 pg_collation_for
24627 ------------------
24628 "default"
24630 SELECT collation for ('foo' COLLATE "de_DE");
24631 pg_collation_for
24632 ------------------
24633 "de_DE"
24634 </programlisting>
24635 </para></entry>
24636 </row>
24638 <row>
24639 <entry role="func_table_entry"><para role="func_signature">
24640 <indexterm>
24641 <primary>to_regclass</primary>
24642 </indexterm>
24643 <function>to_regclass</function> ( <type>text</type> )
24644 <returnvalue>regclass</returnvalue>
24645 </para>
24646 <para>
24647 Translates a textual relation name to its OID. A similar result is
24648 obtained by casting the string to type <type>regclass</type> (see
24649 <xref linkend="datatype-oid"/>); however, this function will return
24650 <literal>NULL</literal> rather than throwing an error if the name is
24651 not found.
24652 </para></entry>
24653 </row>
24655 <row>
24656 <entry role="func_table_entry"><para role="func_signature">
24657 <indexterm>
24658 <primary>to_regcollation</primary>
24659 </indexterm>
24660 <function>to_regcollation</function> ( <type>text</type> )
24661 <returnvalue>regcollation</returnvalue>
24662 </para>
24663 <para>
24664 Translates a textual collation name to its OID. A similar result is
24665 obtained by casting the string to type <type>regcollation</type> (see
24666 <xref linkend="datatype-oid"/>); however, this function will return
24667 <literal>NULL</literal> rather than throwing an error if the name is
24668 not found.
24669 </para></entry>
24670 </row>
24672 <row>
24673 <entry role="func_table_entry"><para role="func_signature">
24674 <indexterm>
24675 <primary>to_regnamespace</primary>
24676 </indexterm>
24677 <function>to_regnamespace</function> ( <type>text</type> )
24678 <returnvalue>regnamespace</returnvalue>
24679 </para>
24680 <para>
24681 Translates a textual schema name to its OID. A similar result is
24682 obtained by casting the string to type <type>regnamespace</type> (see
24683 <xref linkend="datatype-oid"/>); however, this function will return
24684 <literal>NULL</literal> rather than throwing an error if the name is
24685 not found.
24686 </para></entry>
24687 </row>
24689 <row>
24690 <entry role="func_table_entry"><para role="func_signature">
24691 <indexterm>
24692 <primary>to_regoper</primary>
24693 </indexterm>
24694 <function>to_regoper</function> ( <type>text</type> )
24695 <returnvalue>regoper</returnvalue>
24696 </para>
24697 <para>
24698 Translates a textual operator name to its OID. A similar result is
24699 obtained by casting the string to type <type>regoper</type> (see
24700 <xref linkend="datatype-oid"/>); however, this function will return
24701 <literal>NULL</literal> rather than throwing an error if the name is
24702 not found or is ambiguous.
24703 </para></entry>
24704 </row>
24706 <row>
24707 <entry role="func_table_entry"><para role="func_signature">
24708 <indexterm>
24709 <primary>to_regoperator</primary>
24710 </indexterm>
24711 <function>to_regoperator</function> ( <type>text</type> )
24712 <returnvalue>regoperator</returnvalue>
24713 </para>
24714 <para>
24715 Translates a textual operator name (with parameter types) to its OID. A similar result is
24716 obtained by casting the string to type <type>regoperator</type> (see
24717 <xref linkend="datatype-oid"/>); however, this function will return
24718 <literal>NULL</literal> rather than throwing an error if the name is
24719 not found.
24720 </para></entry>
24721 </row>
24723 <row>
24724 <entry role="func_table_entry"><para role="func_signature">
24725 <indexterm>
24726 <primary>to_regproc</primary>
24727 </indexterm>
24728 <function>to_regproc</function> ( <type>text</type> )
24729 <returnvalue>regproc</returnvalue>
24730 </para>
24731 <para>
24732 Translates a textual function or procedure name to its OID. A similar result is
24733 obtained by casting the string to type <type>regproc</type> (see
24734 <xref linkend="datatype-oid"/>); however, this function will return
24735 <literal>NULL</literal> rather than throwing an error if the name is
24736 not found or is ambiguous.
24737 </para></entry>
24738 </row>
24740 <row>
24741 <entry role="func_table_entry"><para role="func_signature">
24742 <indexterm>
24743 <primary>to_regprocedure</primary>
24744 </indexterm>
24745 <function>to_regprocedure</function> ( <type>text</type> )
24746 <returnvalue>regprocedure</returnvalue>
24747 </para>
24748 <para>
24749 Translates a textual function or procedure name (with argument types) to its OID. A similar result is
24750 obtained by casting the string to type <type>regprocedure</type> (see
24751 <xref linkend="datatype-oid"/>); however, this function will return
24752 <literal>NULL</literal> rather than throwing an error if the name is
24753 not found.
24754 </para></entry>
24755 </row>
24757 <row>
24758 <entry role="func_table_entry"><para role="func_signature">
24759 <indexterm>
24760 <primary>to_regrole</primary>
24761 </indexterm>
24762 <function>to_regrole</function> ( <type>text</type> )
24763 <returnvalue>regrole</returnvalue>
24764 </para>
24765 <para>
24766 Translates a textual role name to its OID. A similar result is
24767 obtained by casting the string to type <type>regrole</type> (see
24768 <xref linkend="datatype-oid"/>); however, this function will return
24769 <literal>NULL</literal> rather than throwing an error if the name is
24770 not found.
24771 </para></entry>
24772 </row>
24774 <row>
24775 <entry role="func_table_entry"><para role="func_signature">
24776 <indexterm>
24777 <primary>to_regtype</primary>
24778 </indexterm>
24779 <function>to_regtype</function> ( <type>text</type> )
24780 <returnvalue>regtype</returnvalue>
24781 </para>
24782 <para>
24783 Translates a textual type name to its OID. A similar result is
24784 obtained by casting the string to type <type>regtype</type> (see
24785 <xref linkend="datatype-oid"/>); however, this function will return
24786 <literal>NULL</literal> rather than throwing an error if the name is
24787 not found.
24788 </para></entry>
24789 </row>
24790 </tbody>
24791 </tgroup>
24792 </table>
24794 <para>
24795 Most of the functions that reconstruct (decompile) database objects
24796 have an optional <parameter>pretty</parameter> flag, which
24797 if <literal>true</literal> causes the result to
24798 be <quote>pretty-printed</quote>. Pretty-printing suppresses unnecessary
24799 parentheses and adds whitespace for legibility.
24800 The pretty-printed format is more readable, but the default format
24801 is more likely to be interpreted the same way by future versions of
24802 <productname>PostgreSQL</productname>; so avoid using pretty-printed output
24803 for dump purposes. Passing <literal>false</literal> for
24804 the <parameter>pretty</parameter> parameter yields the same result as
24805 omitting the parameter.
24806 </para>
24808 <table id="functions-info-index-column-props">
24809 <title>Index Column Properties</title>
24810 <tgroup cols="2">
24811 <thead>
24812 <row><entry>Name</entry><entry>Description</entry></row>
24813 </thead>
24814 <tbody>
24815 <row>
24816 <entry><literal>asc</literal></entry>
24817 <entry>Does the column sort in ascending order on a forward scan?
24818 </entry>
24819 </row>
24820 <row>
24821 <entry><literal>desc</literal></entry>
24822 <entry>Does the column sort in descending order on a forward scan?
24823 </entry>
24824 </row>
24825 <row>
24826 <entry><literal>nulls_first</literal></entry>
24827 <entry>Does the column sort with nulls first on a forward scan?
24828 </entry>
24829 </row>
24830 <row>
24831 <entry><literal>nulls_last</literal></entry>
24832 <entry>Does the column sort with nulls last on a forward scan?
24833 </entry>
24834 </row>
24835 <row>
24836 <entry><literal>orderable</literal></entry>
24837 <entry>Does the column possess any defined sort ordering?
24838 </entry>
24839 </row>
24840 <row>
24841 <entry><literal>distance_orderable</literal></entry>
24842 <entry>Can the column be scanned in order by a <quote>distance</quote>
24843 operator, for example <literal>ORDER BY col &lt;-&gt; constant</literal> ?
24844 </entry>
24845 </row>
24846 <row>
24847 <entry><literal>returnable</literal></entry>
24848 <entry>Can the column value be returned by an index-only scan?
24849 </entry>
24850 </row>
24851 <row>
24852 <entry><literal>search_array</literal></entry>
24853 <entry>Does the column natively support <literal>col = ANY(array)</literal>
24854 searches?
24855 </entry>
24856 </row>
24857 <row>
24858 <entry><literal>search_nulls</literal></entry>
24859 <entry>Does the column support <literal>IS NULL</literal> and
24860 <literal>IS NOT NULL</literal> searches?
24861 </entry>
24862 </row>
24863 </tbody>
24864 </tgroup>
24865 </table>
24867 <table id="functions-info-index-props">
24868 <title>Index Properties</title>
24869 <tgroup cols="2">
24870 <thead>
24871 <row><entry>Name</entry><entry>Description</entry></row>
24872 </thead>
24873 <tbody>
24874 <row>
24875 <entry><literal>clusterable</literal></entry>
24876 <entry>Can the index be used in a <literal>CLUSTER</literal> command?
24877 </entry>
24878 </row>
24879 <row>
24880 <entry><literal>index_scan</literal></entry>
24881 <entry>Does the index support plain (non-bitmap) scans?
24882 </entry>
24883 </row>
24884 <row>
24885 <entry><literal>bitmap_scan</literal></entry>
24886 <entry>Does the index support bitmap scans?
24887 </entry>
24888 </row>
24889 <row>
24890 <entry><literal>backward_scan</literal></entry>
24891 <entry>Can the scan direction be changed in mid-scan (to
24892 support <literal>FETCH BACKWARD</literal> on a cursor without
24893 needing materialization)?
24894 </entry>
24895 </row>
24896 </tbody>
24897 </tgroup>
24898 </table>
24900 <table id="functions-info-indexam-props">
24901 <title>Index Access Method Properties</title>
24902 <tgroup cols="2">
24903 <thead>
24904 <row><entry>Name</entry><entry>Description</entry></row>
24905 </thead>
24906 <tbody>
24907 <row>
24908 <entry><literal>can_order</literal></entry>
24909 <entry>Does the access method support <literal>ASC</literal>,
24910 <literal>DESC</literal> and related keywords in
24911 <literal>CREATE INDEX</literal>?
24912 </entry>
24913 </row>
24914 <row>
24915 <entry><literal>can_unique</literal></entry>
24916 <entry>Does the access method support unique indexes?
24917 </entry>
24918 </row>
24919 <row>
24920 <entry><literal>can_multi_col</literal></entry>
24921 <entry>Does the access method support indexes with multiple columns?
24922 </entry>
24923 </row>
24924 <row>
24925 <entry><literal>can_exclude</literal></entry>
24926 <entry>Does the access method support exclusion constraints?
24927 </entry>
24928 </row>
24929 <row>
24930 <entry><literal>can_include</literal></entry>
24931 <entry>Does the access method support the <literal>INCLUDE</literal>
24932 clause of <literal>CREATE INDEX</literal>?
24933 </entry>
24934 </row>
24935 </tbody>
24936 </tgroup>
24937 </table>
24939 <table id="functions-pg-settings-flags">
24940 <title>GUC Flags</title>
24941 <tgroup cols="2">
24942 <thead>
24943 <row><entry>Flag</entry><entry>Description</entry></row>
24944 </thead>
24945 <tbody>
24946 <row>
24947 <entry><literal>EXPLAIN</literal></entry>
24948 <entry>Parameters with this flag are included in
24949 <command>EXPLAIN (SETTINGS)</command> commands.
24950 </entry>
24951 </row>
24952 <row>
24953 <entry><literal>NO_SHOW_ALL</literal></entry>
24954 <entry>Parameters with this flag are excluded from
24955 <command>SHOW ALL</command> commands.
24956 </entry>
24957 </row>
24958 <row>
24959 <entry><literal>NO_RESET</literal></entry>
24960 <entry>Parameters with this flag do not support
24961 <command>RESET</command> commands.
24962 </entry>
24963 </row>
24964 <row>
24965 <entry><literal>NO_RESET_ALL</literal></entry>
24966 <entry>Parameters with this flag are excluded from
24967 <command>RESET ALL</command> commands.
24968 </entry>
24969 </row>
24970 <row>
24971 <entry><literal>NOT_IN_SAMPLE</literal></entry>
24972 <entry>Parameters with this flag are not included in
24973 <filename>postgresql.conf</filename> by default.
24974 </entry>
24975 </row>
24976 <row>
24977 <entry><literal>RUNTIME_COMPUTED</literal></entry>
24978 <entry>Parameters with this flag are runtime-computed ones.
24979 </entry>
24980 </row>
24981 </tbody>
24982 </tgroup>
24983 </table>
24985 </sect2>
24987 <sect2 id="functions-info-object">
24988 <title>Object Information and Addressing Functions</title>
24990 <para>
24991 <xref linkend="functions-info-object-table"/> lists functions related to
24992 database object identification and addressing.
24993 </para>
24995 <table id="functions-info-object-table">
24996 <title>Object Information and Addressing Functions</title>
24997 <tgroup cols="1">
24998 <thead>
24999 <row>
25000 <entry role="func_table_entry"><para role="func_signature">
25001 Function
25002 </para>
25003 <para>
25004 Description
25005 </para></entry>
25006 </row>
25007 </thead>
25009 <tbody>
25010 <row>
25011 <entry role="func_table_entry"><para role="func_signature">
25012 <indexterm>
25013 <primary>pg_describe_object</primary>
25014 </indexterm>
25015 <function>pg_describe_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
25016 <returnvalue>text</returnvalue>
25017 </para>
25018 <para>
25019 Returns a textual description of a database object identified by
25020 catalog OID, object OID, and sub-object ID (such as a column number
25021 within a table; the sub-object ID is zero when referring to a whole
25022 object). This description is intended to be human-readable, and might
25023 be translated, depending on server configuration. This is especially
25024 useful to determine the identity of an object referenced in the
25025 <structname>pg_depend</structname> catalog. This function returns
25026 <literal>NULL</literal> values for undefined objects.
25027 </para></entry>
25028 </row>
25030 <row>
25031 <entry role="func_table_entry"><para role="func_signature">
25032 <indexterm>
25033 <primary>pg_identify_object</primary>
25034 </indexterm>
25035 <function>pg_identify_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
25036 <returnvalue>record</returnvalue>
25037 ( <parameter>type</parameter> <type>text</type>,
25038 <parameter>schema</parameter> <type>text</type>,
25039 <parameter>name</parameter> <type>text</type>,
25040 <parameter>identity</parameter> <type>text</type> )
25041 </para>
25042 <para>
25043 Returns a row containing enough information to uniquely identify the
25044 database object specified by catalog OID, object OID and sub-object
25046 This information is intended to be machine-readable, and is never
25047 translated.
25048 <parameter>type</parameter> identifies the type of database object;
25049 <parameter>schema</parameter> is the schema name that the object
25050 belongs in, or <literal>NULL</literal> for object types that do not
25051 belong to schemas;
25052 <parameter>name</parameter> is the name of the object, quoted if
25053 necessary, if the name (along with schema name, if pertinent) is
25054 sufficient to uniquely identify the object,
25055 otherwise <literal>NULL</literal>;
25056 <parameter>identity</parameter> is the complete object identity, with
25057 the precise format depending on object type, and each name within the
25058 format being schema-qualified and quoted as necessary. Undefined
25059 objects are identified with <literal>NULL</literal> values.
25060 </para></entry>
25061 </row>
25063 <row>
25064 <entry role="func_table_entry"><para role="func_signature">
25065 <indexterm>
25066 <primary>pg_identify_object_as_address</primary>
25067 </indexterm>
25068 <function>pg_identify_object_as_address</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
25069 <returnvalue>record</returnvalue>
25070 ( <parameter>type</parameter> <type>text</type>,
25071 <parameter>object_names</parameter> <type>text[]</type>,
25072 <parameter>object_args</parameter> <type>text[]</type> )
25073 </para>
25074 <para>
25075 Returns a row containing enough information to uniquely identify the
25076 database object specified by catalog OID, object OID and sub-object
25078 The returned information is independent of the current server, that
25079 is, it could be used to identify an identically named object in
25080 another server.
25081 <parameter>type</parameter> identifies the type of database object;
25082 <parameter>object_names</parameter> and
25083 <parameter>object_args</parameter>
25084 are text arrays that together form a reference to the object.
25085 These three values can be passed
25086 to <function>pg_get_object_address</function> to obtain the internal
25087 address of the object.
25088 </para></entry>
25089 </row>
25091 <row>
25092 <entry role="func_table_entry"><para role="func_signature">
25093 <indexterm>
25094 <primary>pg_get_object_address</primary>
25095 </indexterm>
25096 <function>pg_get_object_address</function> ( <parameter>type</parameter> <type>text</type>, <parameter>object_names</parameter> <type>text[]</type>, <parameter>object_args</parameter> <type>text[]</type> )
25097 <returnvalue>record</returnvalue>
25098 ( <parameter>classid</parameter> <type>oid</type>,
25099 <parameter>objid</parameter> <type>oid</type>,
25100 <parameter>objsubid</parameter> <type>integer</type> )
25101 </para>
25102 <para>
25103 Returns a row containing enough information to uniquely identify the
25104 database object specified by a type code and object name and argument
25105 arrays.
25106 The returned values are the ones that would be used in system catalogs
25107 such as <structname>pg_depend</structname>; they can be passed to
25108 other system functions such as <function>pg_describe_object</function>
25109 or <function>pg_identify_object</function>.
25110 <parameter>classid</parameter> is the OID of the system catalog
25111 containing the object;
25112 <parameter>objid</parameter> is the OID of the object itself, and
25113 <parameter>objsubid</parameter> is the sub-object ID, or zero if none.
25114 This function is the inverse
25115 of <function>pg_identify_object_as_address</function>.
25116 Undefined objects are identified with <literal>NULL</literal> values.
25117 </para></entry>
25118 </row>
25119 </tbody>
25120 </tgroup>
25121 </table>
25123 </sect2>
25125 <sect2 id="functions-info-comment">
25126 <title>Comment Information Functions</title>
25128 <indexterm>
25129 <primary>comment</primary>
25130 <secondary sortas="database objects">about database objects</secondary>
25131 </indexterm>
25133 <para>
25134 The functions shown in <xref linkend="functions-info-comment-table"/>
25135 extract comments previously stored with the <xref linkend="sql-comment"/>
25136 command. A null value is returned if no
25137 comment could be found for the specified parameters.
25138 </para>
25140 <table id="functions-info-comment-table">
25141 <title>Comment Information Functions</title>
25142 <tgroup cols="1">
25143 <thead>
25144 <row>
25145 <entry role="func_table_entry"><para role="func_signature">
25146 Function
25147 </para>
25148 <para>
25149 Description
25150 </para></entry>
25151 </row>
25152 </thead>
25154 <tbody>
25155 <row>
25156 <entry role="func_table_entry"><para role="func_signature">
25157 <indexterm>
25158 <primary>col_description</primary>
25159 </indexterm>
25160 <function>col_description</function> ( <parameter>table</parameter> <type>oid</type>, <parameter>column</parameter> <type>integer</type> )
25161 <returnvalue>text</returnvalue>
25162 </para>
25163 <para>
25164 Returns the comment for a table column, which is specified by the OID
25165 of its table and its column number.
25166 (<function>obj_description</function> cannot be used for table
25167 columns, since columns do not have OIDs of their own.)
25168 </para></entry>
25169 </row>
25171 <row>
25172 <entry role="func_table_entry"><para role="func_signature">
25173 <indexterm>
25174 <primary>obj_description</primary>
25175 </indexterm>
25176 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
25177 <returnvalue>text</returnvalue>
25178 </para>
25179 <para>
25180 Returns the comment for a database object specified by its OID and the
25181 name of the containing system catalog. For
25182 example, <literal>obj_description(123456, 'pg_class')</literal> would
25183 retrieve the comment for the table with OID 123456.
25184 </para></entry>
25185 </row>
25187 <row>
25188 <entry role="func_table_entry"><para role="func_signature">
25189 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type> )
25190 <returnvalue>text</returnvalue>
25191 </para>
25192 <para>
25193 Returns the comment for a database object specified by its OID alone.
25194 This is <emphasis>deprecated</emphasis> since there is no guarantee
25195 that OIDs are unique across different system catalogs; therefore, the
25196 wrong comment might be returned.
25197 </para></entry>
25198 </row>
25200 <row>
25201 <entry role="func_table_entry"><para role="func_signature">
25202 <indexterm>
25203 <primary>shobj_description</primary>
25204 </indexterm>
25205 <function>shobj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
25206 <returnvalue>text</returnvalue>
25207 </para>
25208 <para>
25209 Returns the comment for a shared database object specified by its OID
25210 and the name of the containing system catalog. This is just
25211 like <function>obj_description</function> except that it is used for
25212 retrieving comments on shared objects (that is, databases, roles, and
25213 tablespaces). Some system catalogs are global to all databases within
25214 each cluster, and the descriptions for objects in them are stored
25215 globally as well.
25216 </para></entry>
25217 </row>
25218 </tbody>
25219 </tgroup>
25220 </table>
25222 </sect2>
25224 <sect2 id="functions-info-validity">
25225 <title>Data Validity Checking Functions</title>
25227 <para>
25228 The functions shown in <xref linkend="functions-info-validity-table"/>
25229 can be helpful for checking validity of proposed input data.
25230 </para>
25232 <table id="functions-info-validity-table">
25233 <title>Data Validity Checking Functions</title>
25234 <tgroup cols="1">
25235 <thead>
25236 <row>
25237 <entry role="func_table_entry"><para role="func_signature">
25238 Function
25239 </para>
25240 <para>
25241 Description
25242 </para>
25243 <para>
25244 Example(s)
25245 </para></entry>
25246 </row>
25247 </thead>
25249 <tbody>
25250 <row>
25251 <entry role="func_table_entry"><para role="func_signature">
25252 <indexterm>
25253 <primary>pg_input_is_valid</primary>
25254 </indexterm>
25255 <function>pg_input_is_valid</function> (
25256 <parameter>string</parameter> <type>text</type>,
25257 <parameter>type</parameter> <type>text</type>
25259 <returnvalue>boolean</returnvalue>
25260 </para>
25261 <para>
25262 Tests whether the given <parameter>string</parameter> is valid
25263 input for the specified data type, returning true or false.
25264 </para>
25265 <para>
25266 This function will only work as desired if the data type's input
25267 function has been updated to report invalid input as
25268 a <quote>soft</quote> error. Otherwise, invalid input will abort
25269 the transaction, just as if the string had been cast to the type
25270 directly.
25271 </para>
25272 <para>
25273 <literal>pg_input_is_valid('42', 'integer')</literal>
25274 <returnvalue>t</returnvalue>
25275 </para>
25276 <para>
25277 <literal>pg_input_is_valid('42000000000', 'integer')</literal>
25278 <returnvalue>f</returnvalue>
25279 </para>
25280 <para>
25281 <literal>pg_input_is_valid('1234.567', 'numeric(7,4)')</literal>
25282 <returnvalue>f</returnvalue>
25283 </para></entry>
25284 </row>
25285 <row>
25286 <entry role="func_table_entry"><para role="func_signature">
25287 <indexterm>
25288 <primary>pg_input_error_info</primary>
25289 </indexterm>
25290 <function>pg_input_error_info</function> (
25291 <parameter>string</parameter> <type>text</type>,
25292 <parameter>type</parameter> <type>text</type>
25294 <returnvalue>record</returnvalue>
25295 ( <parameter>message</parameter> <type>text</type>,
25296 <parameter>detail</parameter> <type>text</type>,
25297 <parameter>hint</parameter> <type>text</type>,
25298 <parameter>sql_error_code</parameter> <type>text</type> )
25299 </para>
25300 <para>
25301 Tests whether the given <parameter>string</parameter> is valid
25302 input for the specified data type; if not, return the details of
25303 the error that would have been thrown. If the input is valid, the
25304 results are NULL. The inputs are the same as
25305 for <function>pg_input_is_valid</function>.
25306 </para>
25307 <para>
25308 This function will only work as desired if the data type's input
25309 function has been updated to report invalid input as
25310 a <quote>soft</quote> error. Otherwise, invalid input will abort
25311 the transaction, just as if the string had been cast to the type
25312 directly.
25313 </para>
25314 <para>
25315 <literal>select * from pg_input_error_info('42000000000', 'integer')</literal>
25316 <returnvalue></returnvalue>
25317 <programlisting>
25318 message | detail | hint | sql_error_code
25319 ------------------------------------------------------+--------+------+----------------
25320 value "42000000000" is out of range for type integer | | | 22003
25321 </programlisting>
25322 </para>
25323 <para>
25324 <literal>select message, detail from pg_input_error_info('1234.567', 'numeric(7,4)')</literal>
25325 <returnvalue></returnvalue>
25326 <programlisting>
25327 message | detail
25328 ------------------------+----------------------------------&zwsp;-------------------------------------------------
25329 numeric field overflow | A field with precision 7, scale 4 must round to an absolute value less than 10^3.
25330 </programlisting>
25331 </para></entry>
25332 </row>
25333 </tbody>
25334 </tgroup>
25335 </table>
25337 </sect2>
25339 <sect2 id="functions-info-snapshot">
25340 <title>Transaction ID and Snapshot Information Functions</title>
25342 <para>
25343 The functions shown in <xref linkend="functions-pg-snapshot"/>
25344 provide server transaction information in an exportable form. The main
25345 use of these functions is to determine which transactions were committed
25346 between two snapshots.
25347 </para>
25349 <table id="functions-pg-snapshot">
25350 <title>Transaction ID and Snapshot Information Functions</title>
25351 <tgroup cols="1">
25352 <thead>
25353 <row>
25354 <entry role="func_table_entry"><para role="func_signature">
25355 Function
25356 </para>
25357 <para>
25358 Description
25359 </para></entry>
25360 </row>
25361 </thead>
25363 <tbody>
25364 <row>
25365 <entry role="func_table_entry"><para role="func_signature">
25366 <indexterm>
25367 <primary>pg_current_xact_id</primary>
25368 </indexterm>
25369 <function>pg_current_xact_id</function> ()
25370 <returnvalue>xid8</returnvalue>
25371 </para>
25372 <para>
25373 Returns the current transaction's ID. It will assign a new one if the
25374 current transaction does not have one already (because it has not
25375 performed any database updates); see <xref
25376 linkend="transaction-id"/> for details. If executed in a
25377 subtransaction, this will return the top-level transaction ID;
25378 see <xref linkend="subxacts"/> for details.
25379 </para></entry>
25380 </row>
25382 <row>
25383 <entry role="func_table_entry"><para role="func_signature">
25384 <indexterm>
25385 <primary>pg_current_xact_id_if_assigned</primary>
25386 </indexterm>
25387 <function>pg_current_xact_id_if_assigned</function> ()
25388 <returnvalue>xid8</returnvalue>
25389 </para>
25390 <para>
25391 Returns the current transaction's ID, or <literal>NULL</literal> if no
25392 ID is assigned yet. (It's best to use this variant if the transaction
25393 might otherwise be read-only, to avoid unnecessary consumption of an
25394 XID.)
25395 If executed in a subtransaction, this will return the top-level
25396 transaction ID.
25397 </para></entry>
25398 </row>
25400 <row>
25401 <entry role="func_table_entry"><para role="func_signature">
25402 <indexterm>
25403 <primary>pg_xact_status</primary>
25404 </indexterm>
25405 <function>pg_xact_status</function> ( <type>xid8</type> )
25406 <returnvalue>text</returnvalue>
25407 </para>
25408 <para>
25409 Reports the commit status of a recent transaction.
25410 The result is one of <literal>in progress</literal>,
25411 <literal>committed</literal>, or <literal>aborted</literal>,
25412 provided that the transaction is recent enough that the system retains
25413 the commit status of that transaction.
25414 If it is old enough that no references to the transaction survive in
25415 the system and the commit status information has been discarded, the
25416 result is <literal>NULL</literal>.
25417 Applications might use this function, for example, to determine
25418 whether their transaction committed or aborted after the application
25419 and database server become disconnected while
25420 a <literal>COMMIT</literal> is in progress.
25421 Note that prepared transactions are reported as <literal>in
25422 progress</literal>; applications must check <link
25423 linkend="view-pg-prepared-xacts"><structname>pg_prepared_xacts</structname></link>
25424 if they need to determine whether a transaction ID belongs to a
25425 prepared transaction.
25426 </para></entry>
25427 </row>
25429 <row>
25430 <entry role="func_table_entry"><para role="func_signature">
25431 <indexterm>
25432 <primary>pg_current_snapshot</primary>
25433 </indexterm>
25434 <function>pg_current_snapshot</function> ()
25435 <returnvalue>pg_snapshot</returnvalue>
25436 </para>
25437 <para>
25438 Returns a current <firstterm>snapshot</firstterm>, a data structure
25439 showing which transaction IDs are now in-progress.
25440 Only top-level transaction IDs are included in the snapshot;
25441 subtransaction IDs are not shown; see <xref linkend="subxacts"/>
25442 for details.
25443 </para></entry>
25444 </row>
25446 <row>
25447 <entry role="func_table_entry"><para role="func_signature">
25448 <indexterm>
25449 <primary>pg_snapshot_xip</primary>
25450 </indexterm>
25451 <function>pg_snapshot_xip</function> ( <type>pg_snapshot</type> )
25452 <returnvalue>setof xid8</returnvalue>
25453 </para>
25454 <para>
25455 Returns the set of in-progress transaction IDs contained in a snapshot.
25456 </para></entry>
25457 </row>
25459 <row>
25460 <entry role="func_table_entry"><para role="func_signature">
25461 <indexterm>
25462 <primary>pg_snapshot_xmax</primary>
25463 </indexterm>
25464 <function>pg_snapshot_xmax</function> ( <type>pg_snapshot</type> )
25465 <returnvalue>xid8</returnvalue>
25466 </para>
25467 <para>
25468 Returns the <structfield>xmax</structfield> of a snapshot.
25469 </para></entry>
25470 </row>
25472 <row>
25473 <entry role="func_table_entry"><para role="func_signature">
25474 <indexterm>
25475 <primary>pg_snapshot_xmin</primary>
25476 </indexterm>
25477 <function>pg_snapshot_xmin</function> ( <type>pg_snapshot</type> )
25478 <returnvalue>xid8</returnvalue>
25479 </para>
25480 <para>
25481 Returns the <structfield>xmin</structfield> of a snapshot.
25482 </para></entry>
25483 </row>
25485 <row>
25486 <entry role="func_table_entry"><para role="func_signature">
25487 <indexterm>
25488 <primary>pg_visible_in_snapshot</primary>
25489 </indexterm>
25490 <function>pg_visible_in_snapshot</function> ( <type>xid8</type>, <type>pg_snapshot</type> )
25491 <returnvalue>boolean</returnvalue>
25492 </para>
25493 <para>
25494 Is the given transaction ID <firstterm>visible</firstterm> according
25495 to this snapshot (that is, was it completed before the snapshot was
25496 taken)? Note that this function will not give the correct answer for
25497 a subtransaction ID (subxid); see <xref linkend="subxacts"/> for
25498 details.
25499 </para></entry>
25500 </row>
25501 </tbody>
25502 </tgroup>
25503 </table>
25505 <para>
25506 The internal transaction ID type <type>xid</type> is 32 bits wide and
25507 wraps around every 4 billion transactions. However,
25508 the functions shown in <xref linkend="functions-pg-snapshot"/> use a
25509 64-bit type <type>xid8</type> that does not wrap around during the life
25510 of an installation and can be converted to <type>xid</type> by casting if
25511 required; see <xref linkend="transaction-id"/> for details.
25512 The data type <type>pg_snapshot</type> stores information about
25513 transaction ID visibility at a particular moment in time. Its components
25514 are described in <xref linkend="functions-pg-snapshot-parts"/>.
25515 <type>pg_snapshot</type>'s textual representation is
25516 <literal><replaceable>xmin</replaceable>:<replaceable>xmax</replaceable>:<replaceable>xip_list</replaceable></literal>.
25517 For example <literal>10:20:10,14,15</literal> means
25518 <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
25519 </para>
25521 <table id="functions-pg-snapshot-parts">
25522 <title>Snapshot Components</title>
25523 <tgroup cols="2">
25524 <thead>
25525 <row>
25526 <entry>Name</entry>
25527 <entry>Description</entry>
25528 </row>
25529 </thead>
25531 <tbody>
25532 <row>
25533 <entry><structfield>xmin</structfield></entry>
25534 <entry>
25535 Lowest transaction ID that was still active. All transaction IDs
25536 less than <structfield>xmin</structfield> are either committed and visible,
25537 or rolled back and dead.
25538 </entry>
25539 </row>
25541 <row>
25542 <entry><structfield>xmax</structfield></entry>
25543 <entry>
25544 One past the highest completed transaction ID. All transaction IDs
25545 greater than or equal to <structfield>xmax</structfield> had not yet
25546 completed as of the time of the snapshot, and thus are invisible.
25547 </entry>
25548 </row>
25550 <row>
25551 <entry><structfield>xip_list</structfield></entry>
25552 <entry>
25553 Transactions in progress at the time of the snapshot. A transaction
25554 ID that is <literal>xmin &lt;= <replaceable>X</replaceable> &lt;
25555 xmax</literal> and not in this list was already completed at the time
25556 of the snapshot, and thus is either visible or dead according to its
25557 commit status. This list does not include the transaction IDs of
25558 subtransactions (subxids).
25559 </entry>
25560 </row>
25561 </tbody>
25562 </tgroup>
25563 </table>
25565 <para>
25566 In releases of <productname>PostgreSQL</productname> before 13 there was
25567 no <type>xid8</type> type, so variants of these functions were provided
25568 that used <type>bigint</type> to represent a 64-bit XID, with a
25569 correspondingly distinct snapshot data type <type>txid_snapshot</type>.
25570 These older functions have <literal>txid</literal> in their names. They
25571 are still supported for backward compatibility, but may be removed from a
25572 future release. See <xref linkend="functions-txid-snapshot"/>.
25573 </para>
25575 <table id="functions-txid-snapshot">
25576 <title>Deprecated Transaction ID and Snapshot Information Functions</title>
25577 <tgroup cols="1">
25578 <thead>
25579 <row>
25580 <entry role="func_table_entry"><para role="func_signature">
25581 Function
25582 </para>
25583 <para>
25584 Description
25585 </para></entry>
25586 </row>
25587 </thead>
25589 <tbody>
25590 <row>
25591 <entry role="func_table_entry"><para role="func_signature">
25592 <indexterm>
25593 <primary>txid_current</primary>
25594 </indexterm>
25595 <function>txid_current</function> ()
25596 <returnvalue>bigint</returnvalue>
25597 </para>
25598 <para>
25599 See <function>pg_current_xact_id()</function>.
25600 </para></entry>
25601 </row>
25603 <row>
25604 <entry role="func_table_entry"><para role="func_signature">
25605 <indexterm>
25606 <primary>txid_current_if_assigned</primary>
25607 </indexterm>
25608 <function>txid_current_if_assigned</function> ()
25609 <returnvalue>bigint</returnvalue>
25610 </para>
25611 <para>
25612 See <function>pg_current_xact_id_if_assigned()</function>.
25613 </para></entry>
25614 </row>
25616 <row>
25617 <entry role="func_table_entry"><para role="func_signature">
25618 <indexterm>
25619 <primary>txid_current_snapshot</primary>
25620 </indexterm>
25621 <function>txid_current_snapshot</function> ()
25622 <returnvalue>txid_snapshot</returnvalue>
25623 </para>
25624 <para>
25625 See <function>pg_current_snapshot()</function>.
25626 </para></entry>
25627 </row>
25629 <row>
25630 <entry role="func_table_entry"><para role="func_signature">
25631 <indexterm>
25632 <primary>txid_snapshot_xip</primary>
25633 </indexterm>
25634 <function>txid_snapshot_xip</function> ( <type>txid_snapshot</type> )
25635 <returnvalue>setof bigint</returnvalue>
25636 </para>
25637 <para>
25638 See <function>pg_snapshot_xip()</function>.
25639 </para></entry>
25640 </row>
25642 <row>
25643 <entry role="func_table_entry"><para role="func_signature">
25644 <indexterm>
25645 <primary>txid_snapshot_xmax</primary>
25646 </indexterm>
25647 <function>txid_snapshot_xmax</function> ( <type>txid_snapshot</type> )
25648 <returnvalue>bigint</returnvalue>
25649 </para>
25650 <para>
25651 See <function>pg_snapshot_xmax()</function>.
25652 </para></entry>
25653 </row>
25655 <row>
25656 <entry role="func_table_entry"><para role="func_signature">
25657 <indexterm>
25658 <primary>txid_snapshot_xmin</primary>
25659 </indexterm>
25660 <function>txid_snapshot_xmin</function> ( <type>txid_snapshot</type> )
25661 <returnvalue>bigint</returnvalue>
25662 </para>
25663 <para>
25664 See <function>pg_snapshot_xmin()</function>.
25665 </para></entry>
25666 </row>
25668 <row>
25669 <entry role="func_table_entry"><para role="func_signature">
25670 <indexterm>
25671 <primary>txid_visible_in_snapshot</primary>
25672 </indexterm>
25673 <function>txid_visible_in_snapshot</function> ( <type>bigint</type>, <type>txid_snapshot</type> )
25674 <returnvalue>boolean</returnvalue>
25675 </para>
25676 <para>
25677 See <function>pg_visible_in_snapshot()</function>.
25678 </para></entry>
25679 </row>
25681 <row>
25682 <entry role="func_table_entry"><para role="func_signature">
25683 <indexterm>
25684 <primary>txid_status</primary>
25685 </indexterm>
25686 <function>txid_status</function> ( <type>bigint</type> )
25687 <returnvalue>text</returnvalue>
25688 </para>
25689 <para>
25690 See <function>pg_xact_status()</function>.
25691 </para></entry>
25692 </row>
25693 </tbody>
25694 </tgroup>
25695 </table>
25697 </sect2>
25699 <sect2 id="functions-info-commit-timestamp">
25700 <title>Committed Transaction Information Functions</title>
25702 <para>
25703 The functions shown in <xref linkend="functions-commit-timestamp"/>
25704 provide information about when past transactions were committed.
25705 They only provide useful data when the
25706 <xref linkend="guc-track-commit-timestamp"/> configuration option is
25707 enabled, and only for transactions that were committed after it was
25708 enabled. Commit timestamp information is routinely removed during
25709 vacuum.
25710 </para>
25712 <table id="functions-commit-timestamp">
25713 <title>Committed Transaction Information Functions</title>
25714 <tgroup cols="1">
25715 <thead>
25716 <row>
25717 <entry role="func_table_entry"><para role="func_signature">
25718 Function
25719 </para>
25720 <para>
25721 Description
25722 </para></entry>
25723 </row>
25724 </thead>
25726 <tbody>
25727 <row>
25728 <entry role="func_table_entry"><para role="func_signature">
25729 <indexterm>
25730 <primary>pg_xact_commit_timestamp</primary>
25731 </indexterm>
25732 <function>pg_xact_commit_timestamp</function> ( <type>xid</type> )
25733 <returnvalue>timestamp with time zone</returnvalue>
25734 </para>
25735 <para>
25736 Returns the commit timestamp of a transaction.
25737 </para></entry>
25738 </row>
25740 <row>
25741 <entry role="func_table_entry"><para role="func_signature">
25742 <indexterm>
25743 <primary>pg_xact_commit_timestamp_origin</primary>
25744 </indexterm>
25745 <function>pg_xact_commit_timestamp_origin</function> ( <type>xid</type> )
25746 <returnvalue>record</returnvalue>
25747 ( <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
25748 <parameter>roident</parameter> <type>oid</type>)
25749 </para>
25750 <para>
25751 Returns the commit timestamp and replication origin of a transaction.
25752 </para></entry>
25753 </row>
25755 <row>
25756 <entry role="func_table_entry"><para role="func_signature">
25757 <indexterm>
25758 <primary>pg_last_committed_xact</primary>
25759 </indexterm>
25760 <function>pg_last_committed_xact</function> ()
25761 <returnvalue>record</returnvalue>
25762 ( <parameter>xid</parameter> <type>xid</type>,
25763 <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
25764 <parameter>roident</parameter> <type>oid</type> )
25765 </para>
25766 <para>
25767 Returns the transaction ID, commit timestamp and replication origin
25768 of the latest committed transaction.
25769 </para></entry>
25770 </row>
25771 </tbody>
25772 </tgroup>
25773 </table>
25775 </sect2>
25777 <sect2 id="functions-info-controldata">
25778 <title>Control Data Functions</title>
25780 <para>
25781 The functions shown in <xref linkend="functions-controldata"/>
25782 print information initialized during <command>initdb</command>, such
25783 as the catalog version. They also show information about write-ahead
25784 logging and checkpoint processing. This information is cluster-wide,
25785 not specific to any one database. These functions provide most of the same
25786 information, from the same source, as the
25787 <xref linkend="app-pgcontroldata"/> application.
25788 </para>
25790 <table id="functions-controldata">
25791 <title>Control Data Functions</title>
25792 <tgroup cols="1">
25793 <thead>
25794 <row>
25795 <entry role="func_table_entry"><para role="func_signature">
25796 Function
25797 </para>
25798 <para>
25799 Description
25800 </para></entry>
25801 </row>
25802 </thead>
25804 <tbody>
25805 <row>
25806 <entry role="func_table_entry"><para role="func_signature">
25807 <indexterm>
25808 <primary>age</primary>
25809 </indexterm>
25810 <function>age</function> ( <type>xid</type> )
25811 <returnvalue>integer</returnvalue>
25812 </para>
25813 <para>
25814 Returns the number of transactions between the supplied
25815 transaction id and the current transaction counter.
25816 </para></entry>
25817 </row>
25819 <row>
25820 <entry role="func_table_entry"><para role="func_signature">
25821 <indexterm>
25822 <primary>mxid_age</primary>
25823 </indexterm>
25824 <function>mxid_age</function> ( <type>xid</type> )
25825 <returnvalue>integer</returnvalue>
25826 </para>
25827 <para>
25828 Returns the number of multixacts IDs between the supplied
25829 multixact ID and the current multixacts counter.
25830 </para></entry>
25831 </row>
25833 <row>
25834 <entry role="func_table_entry"><para role="func_signature">
25835 <indexterm>
25836 <primary>pg_control_checkpoint</primary>
25837 </indexterm>
25838 <function>pg_control_checkpoint</function> ()
25839 <returnvalue>record</returnvalue>
25840 </para>
25841 <para>
25842 Returns information about current checkpoint state, as shown in
25843 <xref linkend="functions-pg-control-checkpoint"/>.
25844 </para></entry>
25845 </row>
25847 <row>
25848 <entry role="func_table_entry"><para role="func_signature">
25849 <indexterm>
25850 <primary>pg_control_system</primary>
25851 </indexterm>
25852 <function>pg_control_system</function> ()
25853 <returnvalue>record</returnvalue>
25854 </para>
25855 <para>
25856 Returns information about current control file state, as shown in
25857 <xref linkend="functions-pg-control-system"/>.
25858 </para></entry>
25859 </row>
25861 <row>
25862 <entry role="func_table_entry"><para role="func_signature">
25863 <indexterm>
25864 <primary>pg_control_init</primary>
25865 </indexterm>
25866 <function>pg_control_init</function> ()
25867 <returnvalue>record</returnvalue>
25868 </para>
25869 <para>
25870 Returns information about cluster initialization state, as shown in
25871 <xref linkend="functions-pg-control-init"/>.
25872 </para></entry>
25873 </row>
25875 <row>
25876 <entry role="func_table_entry"><para role="func_signature">
25877 <indexterm>
25878 <primary>pg_control_recovery</primary>
25879 </indexterm>
25880 <function>pg_control_recovery</function> ()
25881 <returnvalue>record</returnvalue>
25882 </para>
25883 <para>
25884 Returns information about recovery state, as shown in
25885 <xref linkend="functions-pg-control-recovery"/>.
25886 </para></entry>
25887 </row>
25888 </tbody>
25889 </tgroup>
25890 </table>
25892 <table id="functions-pg-control-checkpoint">
25893 <title><function>pg_control_checkpoint</function> Output Columns</title>
25894 <tgroup cols="2">
25895 <thead>
25896 <row>
25897 <entry>Column Name</entry>
25898 <entry>Data Type</entry>
25899 </row>
25900 </thead>
25902 <tbody>
25904 <row>
25905 <entry><structfield>checkpoint_lsn</structfield></entry>
25906 <entry><type>pg_lsn</type></entry>
25907 </row>
25909 <row>
25910 <entry><structfield>redo_lsn</structfield></entry>
25911 <entry><type>pg_lsn</type></entry>
25912 </row>
25914 <row>
25915 <entry><structfield>redo_wal_file</structfield></entry>
25916 <entry><type>text</type></entry>
25917 </row>
25919 <row>
25920 <entry><structfield>timeline_id</structfield></entry>
25921 <entry><type>integer</type></entry>
25922 </row>
25924 <row>
25925 <entry><structfield>prev_timeline_id</structfield></entry>
25926 <entry><type>integer</type></entry>
25927 </row>
25929 <row>
25930 <entry><structfield>full_page_writes</structfield></entry>
25931 <entry><type>boolean</type></entry>
25932 </row>
25934 <row>
25935 <entry><structfield>next_xid</structfield></entry>
25936 <entry><type>text</type></entry>
25937 </row>
25939 <row>
25940 <entry><structfield>next_oid</structfield></entry>
25941 <entry><type>oid</type></entry>
25942 </row>
25944 <row>
25945 <entry><structfield>next_multixact_id</structfield></entry>
25946 <entry><type>xid</type></entry>
25947 </row>
25949 <row>
25950 <entry><structfield>next_multi_offset</structfield></entry>
25951 <entry><type>xid</type></entry>
25952 </row>
25954 <row>
25955 <entry><structfield>oldest_xid</structfield></entry>
25956 <entry><type>xid</type></entry>
25957 </row>
25959 <row>
25960 <entry><structfield>oldest_xid_dbid</structfield></entry>
25961 <entry><type>oid</type></entry>
25962 </row>
25964 <row>
25965 <entry><structfield>oldest_active_xid</structfield></entry>
25966 <entry><type>xid</type></entry>
25967 </row>
25969 <row>
25970 <entry><structfield>oldest_multi_xid</structfield></entry>
25971 <entry><type>xid</type></entry>
25972 </row>
25974 <row>
25975 <entry><structfield>oldest_multi_dbid</structfield></entry>
25976 <entry><type>oid</type></entry>
25977 </row>
25979 <row>
25980 <entry><structfield>oldest_commit_ts_xid</structfield></entry>
25981 <entry><type>xid</type></entry>
25982 </row>
25984 <row>
25985 <entry><structfield>newest_commit_ts_xid</structfield></entry>
25986 <entry><type>xid</type></entry>
25987 </row>
25989 <row>
25990 <entry><structfield>checkpoint_time</structfield></entry>
25991 <entry><type>timestamp with time zone</type></entry>
25992 </row>
25994 </tbody>
25995 </tgroup>
25996 </table>
25998 <table id="functions-pg-control-system">
25999 <title><function>pg_control_system</function> Output Columns</title>
26000 <tgroup cols="2">
26001 <thead>
26002 <row>
26003 <entry>Column Name</entry>
26004 <entry>Data Type</entry>
26005 </row>
26006 </thead>
26008 <tbody>
26010 <row>
26011 <entry><structfield>pg_control_version</structfield></entry>
26012 <entry><type>integer</type></entry>
26013 </row>
26015 <row>
26016 <entry><structfield>catalog_version_no</structfield></entry>
26017 <entry><type>integer</type></entry>
26018 </row>
26020 <row>
26021 <entry><structfield>system_identifier</structfield></entry>
26022 <entry><type>bigint</type></entry>
26023 </row>
26025 <row>
26026 <entry><structfield>pg_control_last_modified</structfield></entry>
26027 <entry><type>timestamp with time zone</type></entry>
26028 </row>
26030 </tbody>
26031 </tgroup>
26032 </table>
26034 <table id="functions-pg-control-init">
26035 <title><function>pg_control_init</function> Output Columns</title>
26036 <tgroup cols="2">
26037 <thead>
26038 <row>
26039 <entry>Column Name</entry>
26040 <entry>Data Type</entry>
26041 </row>
26042 </thead>
26044 <tbody>
26046 <row>
26047 <entry><structfield>max_data_alignment</structfield></entry>
26048 <entry><type>integer</type></entry>
26049 </row>
26051 <row>
26052 <entry><structfield>database_block_size</structfield></entry>
26053 <entry><type>integer</type></entry>
26054 </row>
26056 <row>
26057 <entry><structfield>blocks_per_segment</structfield></entry>
26058 <entry><type>integer</type></entry>
26059 </row>
26061 <row>
26062 <entry><structfield>wal_block_size</structfield></entry>
26063 <entry><type>integer</type></entry>
26064 </row>
26066 <row>
26067 <entry><structfield>bytes_per_wal_segment</structfield></entry>
26068 <entry><type>integer</type></entry>
26069 </row>
26071 <row>
26072 <entry><structfield>max_identifier_length</structfield></entry>
26073 <entry><type>integer</type></entry>
26074 </row>
26076 <row>
26077 <entry><structfield>max_index_columns</structfield></entry>
26078 <entry><type>integer</type></entry>
26079 </row>
26081 <row>
26082 <entry><structfield>max_toast_chunk_size</structfield></entry>
26083 <entry><type>integer</type></entry>
26084 </row>
26086 <row>
26087 <entry><structfield>large_object_chunk_size</structfield></entry>
26088 <entry><type>integer</type></entry>
26089 </row>
26091 <row>
26092 <entry><structfield>float8_pass_by_value</structfield></entry>
26093 <entry><type>boolean</type></entry>
26094 </row>
26096 <row>
26097 <entry><structfield>data_page_checksum_version</structfield></entry>
26098 <entry><type>integer</type></entry>
26099 </row>
26101 </tbody>
26102 </tgroup>
26103 </table>
26105 <table id="functions-pg-control-recovery">
26106 <title><function>pg_control_recovery</function> Output Columns</title>
26107 <tgroup cols="2">
26108 <thead>
26109 <row>
26110 <entry>Column Name</entry>
26111 <entry>Data Type</entry>
26112 </row>
26113 </thead>
26115 <tbody>
26117 <row>
26118 <entry><structfield>min_recovery_end_lsn</structfield></entry>
26119 <entry><type>pg_lsn</type></entry>
26120 </row>
26122 <row>
26123 <entry><structfield>min_recovery_end_timeline</structfield></entry>
26124 <entry><type>integer</type></entry>
26125 </row>
26127 <row>
26128 <entry><structfield>backup_start_lsn</structfield></entry>
26129 <entry><type>pg_lsn</type></entry>
26130 </row>
26132 <row>
26133 <entry><structfield>backup_end_lsn</structfield></entry>
26134 <entry><type>pg_lsn</type></entry>
26135 </row>
26137 <row>
26138 <entry><structfield>end_of_backup_record_required</structfield></entry>
26139 <entry><type>boolean</type></entry>
26140 </row>
26142 </tbody>
26143 </tgroup>
26144 </table>
26146 </sect2>
26148 </sect1>
26150 <sect1 id="functions-admin">
26151 <title>System Administration Functions</title>
26153 <para>
26154 The functions described in this section are used to control and
26155 monitor a <productname>PostgreSQL</productname> installation.
26156 </para>
26158 <sect2 id="functions-admin-set">
26159 <title>Configuration Settings Functions</title>
26161 <indexterm>
26162 <primary>SET</primary>
26163 </indexterm>
26165 <indexterm>
26166 <primary>SHOW</primary>
26167 </indexterm>
26169 <indexterm>
26170 <primary>configuration</primary>
26171 <secondary sortas="server">of the server</secondary>
26172 <tertiary>functions</tertiary>
26173 </indexterm>
26175 <para>
26176 <xref linkend="functions-admin-set-table"/> shows the functions
26177 available to query and alter run-time configuration parameters.
26178 </para>
26180 <table id="functions-admin-set-table">
26181 <title>Configuration Settings Functions</title>
26182 <tgroup cols="1">
26183 <thead>
26184 <row>
26185 <entry role="func_table_entry"><para role="func_signature">
26186 Function
26187 </para>
26188 <para>
26189 Description
26190 </para>
26191 <para>
26192 Example(s)
26193 </para></entry>
26194 </row>
26195 </thead>
26197 <tbody>
26198 <row>
26199 <entry role="func_table_entry"><para role="func_signature">
26200 <indexterm>
26201 <primary>current_setting</primary>
26202 </indexterm>
26203 <function>current_setting</function> ( <parameter>setting_name</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
26204 <returnvalue>text</returnvalue>
26205 </para>
26206 <para>
26207 Returns the current value of the
26208 setting <parameter>setting_name</parameter>. If there is no such
26209 setting, <function>current_setting</function> throws an error
26210 unless <parameter>missing_ok</parameter> is supplied and
26211 is <literal>true</literal> (in which case NULL is returned).
26212 This function corresponds to
26213 the <acronym>SQL</acronym> command <xref linkend="sql-show"/>.
26214 </para>
26215 <para>
26216 <literal>current_setting('datestyle')</literal>
26217 <returnvalue>ISO, MDY</returnvalue>
26218 </para></entry>
26219 </row>
26221 <row>
26222 <entry role="func_table_entry"><para role="func_signature">
26223 <indexterm>
26224 <primary>set_config</primary>
26225 </indexterm>
26226 <function>set_config</function> (
26227 <parameter>setting_name</parameter> <type>text</type>,
26228 <parameter>new_value</parameter> <type>text</type>,
26229 <parameter>is_local</parameter> <type>boolean</type> )
26230 <returnvalue>text</returnvalue>
26231 </para>
26232 <para>
26233 Sets the parameter <parameter>setting_name</parameter>
26234 to <parameter>new_value</parameter>, and returns that value.
26235 If <parameter>is_local</parameter> is <literal>true</literal>, the new
26236 value will only apply during the current transaction. If you want the
26237 new value to apply for the rest of the current session,
26238 use <literal>false</literal> instead. This function corresponds to
26239 the SQL command <xref linkend="sql-set"/>.
26240 </para>
26241 <para>
26242 <literal>set_config('log_statement_stats', 'off', false)</literal>
26243 <returnvalue>off</returnvalue>
26244 </para></entry>
26245 </row>
26246 </tbody>
26247 </tgroup>
26248 </table>
26250 </sect2>
26252 <sect2 id="functions-admin-signal">
26253 <title>Server Signaling Functions</title>
26255 <indexterm>
26256 <primary>signal</primary>
26257 <secondary sortas="backend">backend processes</secondary>
26258 </indexterm>
26260 <para>
26261 The functions shown in <xref
26262 linkend="functions-admin-signal-table"/> send control signals to
26263 other server processes. Use of these functions is restricted to
26264 superusers by default but access may be granted to others using
26265 <command>GRANT</command>, with noted exceptions.
26266 </para>
26268 <para>
26269 Each of these functions returns <literal>true</literal> if
26270 the signal was successfully sent and <literal>false</literal>
26271 if sending the signal failed.
26272 </para>
26274 <table id="functions-admin-signal-table">
26275 <title>Server Signaling Functions</title>
26276 <tgroup cols="1">
26277 <thead>
26278 <row>
26279 <entry role="func_table_entry"><para role="func_signature">
26280 Function
26281 </para>
26282 <para>
26283 Description
26284 </para></entry>
26285 </row>
26286 </thead>
26288 <tbody>
26289 <row>
26290 <entry role="func_table_entry"><para role="func_signature">
26291 <indexterm>
26292 <primary>pg_cancel_backend</primary>
26293 </indexterm>
26294 <function>pg_cancel_backend</function> ( <parameter>pid</parameter> <type>integer</type> )
26295 <returnvalue>boolean</returnvalue>
26296 </para>
26297 <para>
26298 Cancels the current query of the session whose backend process has the
26299 specified process ID. This is also allowed if the
26300 calling role is a member of the role whose backend is being canceled or
26301 the calling role has privileges of <literal>pg_signal_backend</literal>,
26302 however only superusers can cancel superuser backends.
26303 </para></entry>
26304 </row>
26306 <row>
26307 <entry role="func_table_entry"><para role="func_signature">
26308 <indexterm>
26309 <primary>pg_log_backend_memory_contexts</primary>
26310 </indexterm>
26311 <function>pg_log_backend_memory_contexts</function> ( <parameter>pid</parameter> <type>integer</type> )
26312 <returnvalue>boolean</returnvalue>
26313 </para>
26314 <para>
26315 Requests to log the memory contexts of the backend with the
26316 specified process ID. This function can send the request to
26317 backends and auxiliary processes except logger. These memory contexts
26318 will be logged at
26319 <literal>LOG</literal> message level. They will appear in
26320 the server log based on the log configuration set
26321 (see <xref linkend="runtime-config-logging"/> for more information),
26322 but will not be sent to the client regardless of
26323 <xref linkend="guc-client-min-messages"/>.
26324 </para></entry>
26325 </row>
26327 <row>
26328 <entry role="func_table_entry"><para role="func_signature">
26329 <indexterm>
26330 <primary>pg_reload_conf</primary>
26331 </indexterm>
26332 <function>pg_reload_conf</function> ()
26333 <returnvalue>boolean</returnvalue>
26334 </para>
26335 <para>
26336 Causes all processes of the <productname>PostgreSQL</productname>
26337 server to reload their configuration files. (This is initiated by
26338 sending a <systemitem>SIGHUP</systemitem> signal to the postmaster
26339 process, which in turn sends <systemitem>SIGHUP</systemitem> to each
26340 of its children.) You can use the
26341 <link linkend="view-pg-file-settings"><structname>pg_file_settings</structname></link>,
26342 <link linkend="view-pg-hba-file-rules"><structname>pg_hba_file_rules</structname></link> and
26343 <link linkend="view-pg-ident-file-mappings"><structname>pg_ident_file_mappings</structname></link> views
26344 to check the configuration files for possible errors, before reloading.
26345 </para></entry>
26346 </row>
26348 <row>
26349 <entry role="func_table_entry"><para role="func_signature">
26350 <indexterm>
26351 <primary>pg_rotate_logfile</primary>
26352 </indexterm>
26353 <function>pg_rotate_logfile</function> ()
26354 <returnvalue>boolean</returnvalue>
26355 </para>
26356 <para>
26357 Signals the log-file manager to switch to a new output file
26358 immediately. This works only when the built-in log collector is
26359 running, since otherwise there is no log-file manager subprocess.
26360 </para></entry>
26361 </row>
26363 <row>
26364 <entry role="func_table_entry"><para role="func_signature">
26365 <indexterm>
26366 <primary>pg_terminate_backend</primary>
26367 </indexterm>
26368 <function>pg_terminate_backend</function> ( <parameter>pid</parameter> <type>integer</type>, <parameter>timeout</parameter> <type>bigint</type> <literal>DEFAULT</literal> <literal>0</literal> )
26369 <returnvalue>boolean</returnvalue>
26370 </para>
26371 <para>
26372 Terminates the session whose backend process has the
26373 specified process ID. This is also allowed if the calling role
26374 is a member of the role whose backend is being terminated or the
26375 calling role has privileges of <literal>pg_signal_backend</literal>,
26376 however only superusers can terminate superuser backends.
26377 </para>
26378 <para>
26379 If <parameter>timeout</parameter> is not specified or zero, this
26380 function returns <literal>true</literal> whether the process actually
26381 terminates or not, indicating only that the sending of the signal was
26382 successful. If the <parameter>timeout</parameter> is specified (in
26383 milliseconds) and greater than zero, the function waits until the
26384 process is actually terminated or until the given time has passed. If
26385 the process is terminated, the function
26386 returns <literal>true</literal>. On timeout, a warning is emitted and
26387 <literal>false</literal> is returned.
26388 </para></entry>
26389 </row>
26390 </tbody>
26391 </tgroup>
26392 </table>
26394 <para>
26395 <function>pg_cancel_backend</function> and <function>pg_terminate_backend</function>
26396 send signals (<systemitem>SIGINT</systemitem> or <systemitem>SIGTERM</systemitem>
26397 respectively) to backend processes identified by process ID.
26398 The process ID of an active backend can be found from
26399 the <structfield>pid</structfield> column of the
26400 <structname>pg_stat_activity</structname> view, or by listing the
26401 <command>postgres</command> processes on the server (using
26402 <application>ps</application> on Unix or the <application>Task
26403 Manager</application> on <productname>Windows</productname>).
26404 The role of an active backend can be found from the
26405 <structfield>usename</structfield> column of the
26406 <structname>pg_stat_activity</structname> view.
26407 </para>
26409 <para>
26410 <function>pg_log_backend_memory_contexts</function> can be used
26411 to log the memory contexts of a backend process. For example:
26412 <programlisting>
26413 postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid());
26414 pg_log_backend_memory_contexts
26415 --------------------------------
26417 (1 row)
26418 </programlisting>
26419 One message for each memory context will be logged. For example:
26420 <screen>
26421 LOG: logging memory contexts of PID 10377
26422 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid());
26423 LOG: level: 0; TopMemoryContext: 80800 total in 6 blocks; 14432 free (5 chunks); 66368 used
26424 LOG: level: 1; pgstat TabStatusArray lookup hash table: 8192 total in 1 blocks; 1408 free (0 chunks); 6784 used
26425 LOG: level: 1; TopTransactionContext: 8192 total in 1 blocks; 7720 free (1 chunks); 472 used
26426 LOG: level: 1; RowDescriptionContext: 8192 total in 1 blocks; 6880 free (0 chunks); 1312 used
26427 LOG: level: 1; MessageContext: 16384 total in 2 blocks; 5152 free (0 chunks); 11232 used
26428 LOG: level: 1; Operator class cache: 8192 total in 1 blocks; 512 free (0 chunks); 7680 used
26429 LOG: level: 1; smgr relation table: 16384 total in 2 blocks; 4544 free (3 chunks); 11840 used
26430 LOG: level: 1; TransactionAbortContext: 32768 total in 1 blocks; 32504 free (0 chunks); 264 used
26432 LOG: level: 1; ErrorContext: 8192 total in 1 blocks; 7928 free (3 chunks); 264 used
26433 LOG: Grand total: 1651920 bytes in 201 blocks; 622360 free (88 chunks); 1029560 used
26434 </screen>
26435 If there are more than 100 child contexts under the same parent, the first
26436 100 child contexts are logged, along with a summary of the remaining contexts.
26437 Note that frequent calls to this function could incur significant overhead,
26438 because it may generate a large number of log messages.
26439 </para>
26441 </sect2>
26443 <sect2 id="functions-admin-backup">
26444 <title>Backup Control Functions</title>
26446 <indexterm>
26447 <primary>backup</primary>
26448 </indexterm>
26450 <para>
26451 The functions shown in <xref
26452 linkend="functions-admin-backup-table"/> assist in making on-line backups.
26453 These functions cannot be executed during recovery (except
26454 <function>pg_backup_start</function>,
26455 <function>pg_backup_stop</function>,
26456 and <function>pg_wal_lsn_diff</function>).
26457 </para>
26459 <para>
26460 For details about proper usage of these functions, see
26461 <xref linkend="continuous-archiving"/>.
26462 </para>
26464 <table id="functions-admin-backup-table">
26465 <title>Backup Control Functions</title>
26466 <tgroup cols="1">
26467 <thead>
26468 <row>
26469 <entry role="func_table_entry"><para role="func_signature">
26470 Function
26471 </para>
26472 <para>
26473 Description
26474 </para></entry>
26475 </row>
26476 </thead>
26478 <tbody>
26479 <row>
26480 <entry role="func_table_entry"><para role="func_signature">
26481 <indexterm>
26482 <primary>pg_create_restore_point</primary>
26483 </indexterm>
26484 <function>pg_create_restore_point</function> ( <parameter>name</parameter> <type>text</type> )
26485 <returnvalue>pg_lsn</returnvalue>
26486 </para>
26487 <para>
26488 Creates a named marker record in the write-ahead log that can later be
26489 used as a recovery target, and returns the corresponding write-ahead
26490 log location. The given name can then be used with
26491 <xref linkend="guc-recovery-target-name"/> to specify the point up to
26492 which recovery will proceed. Avoid creating multiple restore points
26493 with the same name, since recovery will stop at the first one whose
26494 name matches the recovery target.
26495 </para>
26496 <para>
26497 This function is restricted to superusers by default, but other users
26498 can be granted EXECUTE to run the function.
26499 </para></entry>
26500 </row>
26502 <row>
26503 <entry role="func_table_entry"><para role="func_signature">
26504 <indexterm>
26505 <primary>pg_current_wal_flush_lsn</primary>
26506 </indexterm>
26507 <function>pg_current_wal_flush_lsn</function> ()
26508 <returnvalue>pg_lsn</returnvalue>
26509 </para>
26510 <para>
26511 Returns the current write-ahead log flush location (see notes below).
26512 </para></entry>
26513 </row>
26515 <row>
26516 <entry role="func_table_entry"><para role="func_signature">
26517 <indexterm>
26518 <primary>pg_current_wal_insert_lsn</primary>
26519 </indexterm>
26520 <function>pg_current_wal_insert_lsn</function> ()
26521 <returnvalue>pg_lsn</returnvalue>
26522 </para>
26523 <para>
26524 Returns the current write-ahead log insert location (see notes below).
26525 </para></entry>
26526 </row>
26528 <row>
26529 <entry role="func_table_entry"><para role="func_signature">
26530 <indexterm>
26531 <primary>pg_current_wal_lsn</primary>
26532 </indexterm>
26533 <function>pg_current_wal_lsn</function> ()
26534 <returnvalue>pg_lsn</returnvalue>
26535 </para>
26536 <para>
26537 Returns the current write-ahead log write location (see notes below).
26538 </para></entry>
26539 </row>
26541 <row>
26542 <entry role="func_table_entry"><para role="func_signature">
26543 <indexterm>
26544 <primary>pg_backup_start</primary>
26545 </indexterm>
26546 <function>pg_backup_start</function> (
26547 <parameter>label</parameter> <type>text</type>
26548 <optional>, <parameter>fast</parameter> <type>boolean</type>
26549 </optional> )
26550 <returnvalue>pg_lsn</returnvalue>
26551 </para>
26552 <para>
26553 Prepares the server to begin an on-line backup. The only required
26554 parameter is an arbitrary user-defined label for the backup.
26555 (Typically this would be the name under which the backup dump file
26556 will be stored.)
26557 If the optional second parameter is given as <literal>true</literal>,
26558 it specifies executing <function>pg_backup_start</function> as quickly
26559 as possible. This forces an immediate checkpoint which will cause a
26560 spike in I/O operations, slowing any concurrently executing queries.
26561 </para>
26562 <para>
26563 This function is restricted to superusers by default, but other users
26564 can be granted EXECUTE to run the function.
26565 </para></entry>
26566 </row>
26568 <row>
26569 <entry role="func_table_entry"><para role="func_signature">
26570 <indexterm>
26571 <primary>pg_backup_stop</primary>
26572 </indexterm>
26573 <function>pg_backup_stop</function> (
26574 <optional><parameter>wait_for_archive</parameter> <type>boolean</type>
26575 </optional> )
26576 <returnvalue>record</returnvalue>
26577 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
26578 <parameter>labelfile</parameter> <type>text</type>,
26579 <parameter>spcmapfile</parameter> <type>text</type> )
26580 </para>
26581 <para>
26582 Finishes performing an on-line backup. The desired contents of the
26583 backup label file and the tablespace map file are returned as part of
26584 the result of the function and must be written to files in the
26585 backup area. These files must not be written to the live data directory
26586 (doing so will cause PostgreSQL to fail to restart in the event of a
26587 crash).
26588 </para>
26589 <para>
26590 There is an optional parameter of type <type>boolean</type>.
26591 If false, the function will return immediately after the backup is
26592 completed, without waiting for WAL to be archived. This behavior is
26593 only useful with backup software that independently monitors WAL
26594 archiving. Otherwise, WAL required to make the backup consistent might
26595 be missing and make the backup useless. By default or when this
26596 parameter is true, <function>pg_backup_stop</function> will wait for
26597 WAL to be archived when archiving is enabled. (On a standby, this
26598 means that it will wait only when <varname>archive_mode</varname> =
26599 <literal>always</literal>. If write activity on the primary is low,
26600 it may be useful to run <function>pg_switch_wal</function> on the
26601 primary in order to trigger an immediate segment switch.)
26602 </para>
26603 <para>
26604 When executed on a primary, this function also creates a backup
26605 history file in the write-ahead log archive area. The history file
26606 includes the label given to <function>pg_backup_start</function>, the
26607 starting and ending write-ahead log locations for the backup, and the
26608 starting and ending times of the backup. After recording the ending
26609 location, the current write-ahead log insertion point is automatically
26610 advanced to the next write-ahead log file, so that the ending
26611 write-ahead log file can be archived immediately to complete the
26612 backup.
26613 </para>
26614 <para>
26615 The result of the function is a single record.
26616 The <parameter>lsn</parameter> column holds the backup's ending
26617 write-ahead log location (which again can be ignored). The second
26618 column returns the contents of the backup label file, and the third
26619 column returns the contents of the tablespace map file. These must be
26620 stored as part of the backup and are required as part of the restore
26621 process.
26622 </para>
26623 <para>
26624 This function is restricted to superusers by default, but other users
26625 can be granted EXECUTE to run the function.
26626 </para></entry>
26627 </row>
26629 <row>
26630 <entry role="func_table_entry"><para role="func_signature">
26631 <indexterm>
26632 <primary>pg_switch_wal</primary>
26633 </indexterm>
26634 <function>pg_switch_wal</function> ()
26635 <returnvalue>pg_lsn</returnvalue>
26636 </para>
26637 <para>
26638 Forces the server to switch to a new write-ahead log file, which
26639 allows the current file to be archived (assuming you are using
26640 continuous archiving). The result is the ending write-ahead log
26641 location plus 1 within the just-completed write-ahead log file. If
26642 there has been no write-ahead log activity since the last write-ahead
26643 log switch, <function>pg_switch_wal</function> does nothing and
26644 returns the start location of the write-ahead log file currently in
26645 use.
26646 </para>
26647 <para>
26648 This function is restricted to superusers by default, but other users
26649 can be granted EXECUTE to run the function.
26650 </para></entry>
26651 </row>
26653 <row>
26654 <entry role="func_table_entry"><para role="func_signature">
26655 <indexterm>
26656 <primary>pg_walfile_name</primary>
26657 </indexterm>
26658 <function>pg_walfile_name</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
26659 <returnvalue>text</returnvalue>
26660 </para>
26661 <para>
26662 Converts a write-ahead log location to the name of the WAL file
26663 holding that location.
26664 </para></entry>
26665 </row>
26667 <row>
26668 <entry role="func_table_entry"><para role="func_signature">
26669 <indexterm>
26670 <primary>pg_walfile_name_offset</primary>
26671 </indexterm>
26672 <function>pg_walfile_name_offset</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
26673 <returnvalue>record</returnvalue>
26674 ( <parameter>file_name</parameter> <type>text</type>,
26675 <parameter>file_offset</parameter> <type>integer</type> )
26676 </para>
26677 <para>
26678 Converts a write-ahead log location to a WAL file name and byte offset
26679 within that file.
26680 </para></entry>
26681 </row>
26683 <row>
26684 <entry role="func_table_entry"><para role="func_signature">
26685 <indexterm>
26686 <primary>pg_split_walfile_name</primary>
26687 </indexterm>
26688 <function>pg_split_walfile_name</function> ( <parameter>file_name</parameter> <type>text</type> )
26689 <returnvalue>record</returnvalue>
26690 ( <parameter>segment_number</parameter> <type>numeric</type>,
26691 <parameter>timeline_id</parameter> <type>bigint</type> )
26692 </para>
26693 <para>
26694 Extracts the sequence number and timeline ID from a WAL file
26695 name.
26696 </para></entry>
26697 </row>
26699 <row>
26700 <entry role="func_table_entry"><para role="func_signature">
26701 <indexterm>
26702 <primary>pg_wal_lsn_diff</primary>
26703 </indexterm>
26704 <function>pg_wal_lsn_diff</function> ( <parameter>lsn1</parameter> <type>pg_lsn</type>, <parameter>lsn2</parameter> <type>pg_lsn</type> )
26705 <returnvalue>numeric</returnvalue>
26706 </para>
26707 <para>
26708 Calculates the difference in bytes (<parameter>lsn1</parameter> - <parameter>lsn2</parameter>) between two write-ahead log
26709 locations. This can be used
26710 with <structname>pg_stat_replication</structname> or some of the
26711 functions shown in <xref linkend="functions-admin-backup-table"/> to
26712 get the replication lag.
26713 </para></entry>
26714 </row>
26715 </tbody>
26716 </tgroup>
26717 </table>
26719 <para>
26720 <function>pg_current_wal_lsn</function> displays the current write-ahead
26721 log write location in the same format used by the above functions.
26722 Similarly, <function>pg_current_wal_insert_lsn</function> displays the
26723 current write-ahead log insertion location
26724 and <function>pg_current_wal_flush_lsn</function> displays the current
26725 write-ahead log flush location. The insertion location is
26726 the <quote>logical</quote> end of the write-ahead log at any instant,
26727 while the write location is the end of what has actually been written out
26728 from the server's internal buffers, and the flush location is the last
26729 location known to be written to durable storage. The write location is the
26730 end of what can be examined from outside the server, and is usually what
26731 you want if you are interested in archiving partially-complete write-ahead
26732 log files. The insertion and flush locations are made available primarily
26733 for server debugging purposes. These are all read-only operations and do
26734 not require superuser permissions.
26735 </para>
26737 <para>
26738 You can use <function>pg_walfile_name_offset</function> to extract the
26739 corresponding write-ahead log file name and byte offset from
26740 a <type>pg_lsn</type> value. For example:
26741 <programlisting>
26742 postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn);
26743 file_name | file_offset
26744 --------------------------+-------------
26745 00000001000000000000000D | 4039624
26746 (1 row)
26747 </programlisting>
26748 Similarly, <function>pg_walfile_name</function> extracts just the write-ahead log file name.
26749 When the given write-ahead log location is exactly at a write-ahead log file boundary, both
26750 these functions return the name of the preceding write-ahead log file.
26751 This is usually the desired behavior for managing write-ahead log archiving
26752 behavior, since the preceding file is the last one that currently
26753 needs to be archived.
26754 </para>
26756 <para>
26757 <function>pg_split_walfile_name</function> is useful to compute a
26758 <acronym>LSN</acronym> from a file offset and WAL file name, for example:
26759 <programlisting>
26760 postgres=# \set file_name '000000010000000100C000AB'
26761 postgres=# \set offset 256
26762 postgres=# SELECT '0/0'::pg_lsn + pd.segment_number * ps.setting::int + :offset AS lsn
26763 FROM pg_split_walfile_name(:'file_name') pd,
26764 pg_show_all_settings() ps
26765 WHERE ps.name = 'wal_segment_size';
26767 ---------------
26768 C001/AB000100
26769 (1 row)
26770 </programlisting>
26771 </para>
26773 </sect2>
26775 <sect2 id="functions-recovery-control">
26776 <title>Recovery Control Functions</title>
26778 <para>
26779 The functions shown in <xref
26780 linkend="functions-recovery-info-table"/> provide information
26781 about the current status of a standby server.
26782 These functions may be executed both during recovery and in normal running.
26783 </para>
26785 <table id="functions-recovery-info-table">
26786 <title>Recovery Information Functions</title>
26787 <tgroup cols="1">
26788 <thead>
26789 <row>
26790 <entry role="func_table_entry"><para role="func_signature">
26791 Function
26792 </para>
26793 <para>
26794 Description
26795 </para></entry>
26796 </row>
26797 </thead>
26799 <tbody>
26800 <row>
26801 <entry role="func_table_entry"><para role="func_signature">
26802 <indexterm>
26803 <primary>pg_is_in_recovery</primary>
26804 </indexterm>
26805 <function>pg_is_in_recovery</function> ()
26806 <returnvalue>boolean</returnvalue>
26807 </para>
26808 <para>
26809 Returns true if recovery is still in progress.
26810 </para></entry>
26811 </row>
26813 <row>
26814 <entry role="func_table_entry"><para role="func_signature">
26815 <indexterm>
26816 <primary>pg_last_wal_receive_lsn</primary>
26817 </indexterm>
26818 <function>pg_last_wal_receive_lsn</function> ()
26819 <returnvalue>pg_lsn</returnvalue>
26820 </para>
26821 <para>
26822 Returns the last write-ahead log location that has been received and
26823 synced to disk by streaming replication. While streaming replication
26824 is in progress this will increase monotonically. If recovery has
26825 completed then this will remain static at the location of the last WAL
26826 record received and synced to disk during recovery. If streaming
26827 replication is disabled, or if it has not yet started, the function
26828 returns <literal>NULL</literal>.
26829 </para></entry>
26830 </row>
26832 <row>
26833 <entry role="func_table_entry"><para role="func_signature">
26834 <indexterm>
26835 <primary>pg_last_wal_replay_lsn</primary>
26836 </indexterm>
26837 <function>pg_last_wal_replay_lsn</function> ()
26838 <returnvalue>pg_lsn</returnvalue>
26839 </para>
26840 <para>
26841 Returns the last write-ahead log location that has been replayed
26842 during recovery. If recovery is still in progress this will increase
26843 monotonically. If recovery has completed then this will remain
26844 static at the location of the last WAL record applied during recovery.
26845 When the server has been started normally without recovery, the
26846 function returns <literal>NULL</literal>.
26847 </para></entry>
26848 </row>
26850 <row>
26851 <entry role="func_table_entry"><para role="func_signature">
26852 <indexterm>
26853 <primary>pg_last_xact_replay_timestamp</primary>
26854 </indexterm>
26855 <function>pg_last_xact_replay_timestamp</function> ()
26856 <returnvalue>timestamp with time zone</returnvalue>
26857 </para>
26858 <para>
26859 Returns the time stamp of the last transaction replayed during
26860 recovery. This is the time at which the commit or abort WAL record
26861 for that transaction was generated on the primary. If no transactions
26862 have been replayed during recovery, the function
26863 returns <literal>NULL</literal>. Otherwise, if recovery is still in
26864 progress this will increase monotonically. If recovery has completed
26865 then this will remain static at the time of the last transaction
26866 applied during recovery. When the server has been started normally
26867 without recovery, the function returns <literal>NULL</literal>.
26868 </para></entry>
26869 </row>
26871 <row>
26872 <entry role="func_table_entry"><para role="func_signature">
26873 <indexterm>
26874 <primary>pg_get_wal_resource_managers</primary>
26875 </indexterm>
26876 <function>pg_get_wal_resource_managers</function> ()
26877 <returnvalue>setof record</returnvalue>
26878 ( <parameter>rm_id</parameter> <type>integer</type>,
26879 <parameter>rm_name</parameter> <type>text</type>,
26880 <parameter>rm_builtin</parameter> <type>boolean</type> )
26881 </para>
26882 <para>
26883 Returns the currently-loaded WAL resource managers in the system. The
26884 column <parameter>rm_builtin</parameter> indicates whether it's a
26885 built-in resource manager, or a custom resource manager loaded by an
26886 extension.
26887 </para></entry>
26888 </row>
26889 </tbody>
26890 </tgroup>
26891 </table>
26893 <para>
26894 The functions shown in <xref
26895 linkend="functions-recovery-control-table"/> control the progress of recovery.
26896 These functions may be executed only during recovery.
26897 </para>
26899 <table id="functions-recovery-control-table">
26900 <title>Recovery Control Functions</title>
26901 <tgroup cols="1">
26902 <thead>
26903 <row>
26904 <entry role="func_table_entry"><para role="func_signature">
26905 Function
26906 </para>
26907 <para>
26908 Description
26909 </para></entry>
26910 </row>
26911 </thead>
26913 <tbody>
26914 <row>
26915 <entry role="func_table_entry"><para role="func_signature">
26916 <indexterm>
26917 <primary>pg_is_wal_replay_paused</primary>
26918 </indexterm>
26919 <function>pg_is_wal_replay_paused</function> ()
26920 <returnvalue>boolean</returnvalue>
26921 </para>
26922 <para>
26923 Returns true if recovery pause is requested.
26924 </para></entry>
26925 </row>
26927 <row>
26928 <entry role="func_table_entry"><para role="func_signature">
26929 <indexterm>
26930 <primary>pg_get_wal_replay_pause_state</primary>
26931 </indexterm>
26932 <function>pg_get_wal_replay_pause_state</function> ()
26933 <returnvalue>text</returnvalue>
26934 </para>
26935 <para>
26936 Returns recovery pause state. The return values are <literal>
26937 not paused</literal> if pause is not requested, <literal>
26938 pause requested</literal> if pause is requested but recovery is
26939 not yet paused, and <literal>paused</literal> if the recovery is
26940 actually paused.
26941 </para></entry>
26942 </row>
26944 <row>
26945 <entry role="func_table_entry"><para role="func_signature">
26946 <indexterm>
26947 <primary>pg_promote</primary>
26948 </indexterm>
26949 <function>pg_promote</function> ( <parameter>wait</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>true</literal>, <parameter>wait_seconds</parameter> <type>integer</type> <literal>DEFAULT</literal> <literal>60</literal> )
26950 <returnvalue>boolean</returnvalue>
26951 </para>
26952 <para>
26953 Promotes a standby server to primary status.
26954 With <parameter>wait</parameter> set to <literal>true</literal> (the
26955 default), the function waits until promotion is completed
26956 or <parameter>wait_seconds</parameter> seconds have passed, and
26957 returns <literal>true</literal> if promotion is successful
26958 and <literal>false</literal> otherwise.
26959 If <parameter>wait</parameter> is set to <literal>false</literal>, the
26960 function returns <literal>true</literal> immediately after sending a
26961 <literal>SIGUSR1</literal> signal to the postmaster to trigger
26962 promotion.
26963 </para>
26964 <para>
26965 This function is restricted to superusers by default, but other users
26966 can be granted EXECUTE to run the function.
26967 </para></entry>
26968 </row>
26970 <row>
26971 <entry role="func_table_entry"><para role="func_signature">
26972 <indexterm>
26973 <primary>pg_wal_replay_pause</primary>
26974 </indexterm>
26975 <function>pg_wal_replay_pause</function> ()
26976 <returnvalue>void</returnvalue>
26977 </para>
26978 <para>
26979 Request to pause recovery. A request doesn't mean that recovery stops
26980 right away. If you want a guarantee that recovery is actually paused,
26981 you need to check for the recovery pause state returned by
26982 <function>pg_get_wal_replay_pause_state()</function>. Note that
26983 <function>pg_is_wal_replay_paused()</function> returns whether a request
26984 is made. While recovery is paused, no further database changes are applied.
26985 If hot standby is active, all new queries will see the same consistent
26986 snapshot of the database, and no further query conflicts will be generated
26987 until recovery is resumed.
26988 </para>
26989 <para>
26990 This function is restricted to superusers by default, but other users
26991 can be granted EXECUTE to run the function.
26992 </para></entry>
26993 </row>
26995 <row>
26996 <entry role="func_table_entry"><para role="func_signature">
26997 <indexterm>
26998 <primary>pg_wal_replay_resume</primary>
26999 </indexterm>
27000 <function>pg_wal_replay_resume</function> ()
27001 <returnvalue>void</returnvalue>
27002 </para>
27003 <para>
27004 Restarts recovery if it was paused.
27005 </para>
27006 <para>
27007 This function is restricted to superusers by default, but other users
27008 can be granted EXECUTE to run the function.
27009 </para></entry>
27010 </row>
27011 </tbody>
27012 </tgroup>
27013 </table>
27015 <para>
27016 <function>pg_wal_replay_pause</function> and
27017 <function>pg_wal_replay_resume</function> cannot be executed while
27018 a promotion is ongoing. If a promotion is triggered while recovery
27019 is paused, the paused state ends and promotion continues.
27020 </para>
27022 <para>
27023 If streaming replication is disabled, the paused state may continue
27024 indefinitely without a problem. If streaming replication is in
27025 progress then WAL records will continue to be received, which will
27026 eventually fill available disk space, depending upon the duration of
27027 the pause, the rate of WAL generation and available disk space.
27028 </para>
27030 </sect2>
27032 <sect2 id="functions-snapshot-synchronization">
27033 <title>Snapshot Synchronization Functions</title>
27035 <para>
27036 <productname>PostgreSQL</productname> allows database sessions to synchronize their
27037 snapshots. A <firstterm>snapshot</firstterm> determines which data is visible to the
27038 transaction that is using the snapshot. Synchronized snapshots are
27039 necessary when two or more sessions need to see identical content in the
27040 database. If two sessions just start their transactions independently,
27041 there is always a possibility that some third transaction commits
27042 between the executions of the two <command>START TRANSACTION</command> commands,
27043 so that one session sees the effects of that transaction and the other
27044 does not.
27045 </para>
27047 <para>
27048 To solve this problem, <productname>PostgreSQL</productname> allows a transaction to
27049 <firstterm>export</firstterm> the snapshot it is using. As long as the exporting
27050 transaction remains open, other transactions can <firstterm>import</firstterm> its
27051 snapshot, and thereby be guaranteed that they see exactly the same view
27052 of the database that the first transaction sees. But note that any
27053 database changes made by any one of these transactions remain invisible
27054 to the other transactions, as is usual for changes made by uncommitted
27055 transactions. So the transactions are synchronized with respect to
27056 pre-existing data, but act normally for changes they make themselves.
27057 </para>
27059 <para>
27060 Snapshots are exported with the <function>pg_export_snapshot</function> function,
27061 shown in <xref linkend="functions-snapshot-synchronization-table"/>, and
27062 imported with the <xref linkend="sql-set-transaction"/> command.
27063 </para>
27065 <table id="functions-snapshot-synchronization-table">
27066 <title>Snapshot Synchronization Functions</title>
27067 <tgroup cols="1">
27068 <thead>
27069 <row>
27070 <entry role="func_table_entry"><para role="func_signature">
27071 Function
27072 </para>
27073 <para>
27074 Description
27075 </para></entry>
27076 </row>
27077 </thead>
27079 <tbody>
27080 <row>
27081 <entry role="func_table_entry"><para role="func_signature">
27082 <indexterm>
27083 <primary>pg_export_snapshot</primary>
27084 </indexterm>
27085 <function>pg_export_snapshot</function> ()
27086 <returnvalue>text</returnvalue>
27087 </para>
27088 <para>
27089 Saves the transaction's current snapshot and returns
27090 a <type>text</type> string identifying the snapshot. This string must
27091 be passed (outside the database) to clients that want to import the
27092 snapshot. The snapshot is available for import only until the end of
27093 the transaction that exported it.
27094 </para>
27095 <para>
27096 A transaction can export more than one snapshot, if needed. Note that
27097 doing so is only useful in <literal>READ COMMITTED</literal>
27098 transactions, since in <literal>REPEATABLE READ</literal> and higher
27099 isolation levels, transactions use the same snapshot throughout their
27100 lifetime. Once a transaction has exported any snapshots, it cannot be
27101 prepared with <xref linkend="sql-prepare-transaction"/>.
27102 </para></entry>
27103 </row>
27104 <row>
27105 <entry role="func_table_entry"><para role="func_signature">
27106 <indexterm>
27107 <primary>pg_log_standby_snapshot</primary>
27108 </indexterm>
27109 <function>pg_log_standby_snapshot</function> ()
27110 <returnvalue>pg_lsn</returnvalue>
27111 </para>
27112 <para>
27113 Take a snapshot of running transactions and write it to WAL, without
27114 having to wait for bgwriter or checkpointer to log one. This is useful
27115 for logical decoding on standby, as logical slot creation has to wait
27116 until such a record is replayed on the standby.
27117 </para></entry>
27118 </row>
27119 </tbody>
27120 </tgroup>
27121 </table>
27123 </sect2>
27125 <sect2 id="functions-replication">
27126 <title>Replication Management Functions</title>
27128 <para>
27129 The functions shown
27130 in <xref linkend="functions-replication-table"/> are for
27131 controlling and interacting with replication features.
27132 See <xref linkend="streaming-replication"/>,
27133 <xref linkend="streaming-replication-slots"/>, and
27134 <xref linkend="replication-origins"/>
27135 for information about the underlying features.
27136 Use of functions for replication origin is only allowed to the
27137 superuser by default, but may be allowed to other users by using the
27138 <literal>GRANT</literal> command.
27139 Use of functions for replication slots is restricted to superusers
27140 and users having <literal>REPLICATION</literal> privilege.
27141 </para>
27143 <para>
27144 Many of these functions have equivalent commands in the replication
27145 protocol; see <xref linkend="protocol-replication"/>.
27146 </para>
27148 <para>
27149 The functions described in
27150 <xref linkend="functions-admin-backup"/>,
27151 <xref linkend="functions-recovery-control"/>, and
27152 <xref linkend="functions-snapshot-synchronization"/>
27153 are also relevant for replication.
27154 </para>
27156 <table id="functions-replication-table">
27157 <title>Replication Management Functions</title>
27158 <tgroup cols="1">
27159 <thead>
27160 <row>
27161 <entry role="func_table_entry"><para role="func_signature">
27162 Function
27163 </para>
27164 <para>
27165 Description
27166 </para></entry>
27167 </row>
27168 </thead>
27170 <tbody>
27171 <row>
27172 <entry role="func_table_entry"><para role="func_signature">
27173 <indexterm>
27174 <primary>pg_create_physical_replication_slot</primary>
27175 </indexterm>
27176 <function>pg_create_physical_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type> <optional>, <parameter>immediately_reserve</parameter> <type>boolean</type>, <parameter>temporary</parameter> <type>boolean</type> </optional> )
27177 <returnvalue>record</returnvalue>
27178 ( <parameter>slot_name</parameter> <type>name</type>,
27179 <parameter>lsn</parameter> <type>pg_lsn</type> )
27180 </para>
27181 <para>
27182 Creates a new physical replication slot named
27183 <parameter>slot_name</parameter>. The optional second parameter,
27184 when <literal>true</literal>, specifies that the <acronym>LSN</acronym> for this
27185 replication slot be reserved immediately; otherwise
27186 the <acronym>LSN</acronym> is reserved on first connection from a streaming
27187 replication client. Streaming changes from a physical slot is only
27188 possible with the streaming-replication protocol &mdash;
27189 see <xref linkend="protocol-replication"/>. The optional third
27190 parameter, <parameter>temporary</parameter>, when set to true, specifies that
27191 the slot should not be permanently stored to disk and is only meant
27192 for use by the current session. Temporary slots are also
27193 released upon any error. This function corresponds
27194 to the replication protocol command <literal>CREATE_REPLICATION_SLOT
27195 ... PHYSICAL</literal>.
27196 </para></entry>
27197 </row>
27199 <row>
27200 <entry role="func_table_entry"><para role="func_signature">
27201 <indexterm>
27202 <primary>pg_drop_replication_slot</primary>
27203 </indexterm>
27204 <function>pg_drop_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type> )
27205 <returnvalue>void</returnvalue>
27206 </para>
27207 <para>
27208 Drops the physical or logical replication slot
27209 named <parameter>slot_name</parameter>. Same as replication protocol
27210 command <literal>DROP_REPLICATION_SLOT</literal>. For logical slots, this must
27211 be called while connected to the same database the slot was created on.
27212 </para></entry>
27213 </row>
27215 <row>
27216 <entry role="func_table_entry"><para role="func_signature">
27217 <indexterm>
27218 <primary>pg_create_logical_replication_slot</primary>
27219 </indexterm>
27220 <function>pg_create_logical_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>plugin</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type>, <parameter>twophase</parameter> <type>boolean</type> </optional> )
27221 <returnvalue>record</returnvalue>
27222 ( <parameter>slot_name</parameter> <type>name</type>,
27223 <parameter>lsn</parameter> <type>pg_lsn</type> )
27224 </para>
27225 <para>
27226 Creates a new logical (decoding) replication slot named
27227 <parameter>slot_name</parameter> using the output plugin
27228 <parameter>plugin</parameter>. The optional third
27229 parameter, <parameter>temporary</parameter>, when set to true, specifies that
27230 the slot should not be permanently stored to disk and is only meant
27231 for use by the current session. Temporary slots are also
27232 released upon any error. The optional fourth parameter,
27233 <parameter>twophase</parameter>, when set to true, specifies
27234 that the decoding of prepared transactions is enabled for this
27235 slot. A call to this function has the same effect as the replication
27236 protocol command <literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>.
27237 </para></entry>
27238 </row>
27240 <row>
27241 <entry role="func_table_entry"><para role="func_signature">
27242 <indexterm>
27243 <primary>pg_copy_physical_replication_slot</primary>
27244 </indexterm>
27245 <function>pg_copy_physical_replication_slot</function> ( <parameter>src_slot_name</parameter> <type>name</type>, <parameter>dst_slot_name</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type> </optional> )
27246 <returnvalue>record</returnvalue>
27247 ( <parameter>slot_name</parameter> <type>name</type>,
27248 <parameter>lsn</parameter> <type>pg_lsn</type> )
27249 </para>
27250 <para>
27251 Copies an existing physical replication slot named <parameter>src_slot_name</parameter>
27252 to a physical replication slot named <parameter>dst_slot_name</parameter>.
27253 The copied physical slot starts to reserve WAL from the same <acronym>LSN</acronym> as the
27254 source slot.
27255 <parameter>temporary</parameter> is optional. If <parameter>temporary</parameter>
27256 is omitted, the same value as the source slot is used.
27257 </para></entry>
27258 </row>
27260 <row>
27261 <entry role="func_table_entry"><para role="func_signature">
27262 <indexterm>
27263 <primary>pg_copy_logical_replication_slot</primary>
27264 </indexterm>
27265 <function>pg_copy_logical_replication_slot</function> ( <parameter>src_slot_name</parameter> <type>name</type>, <parameter>dst_slot_name</parameter> <type>name</type> <optional>, <parameter>temporary</parameter> <type>boolean</type> <optional>, <parameter>plugin</parameter> <type>name</type> </optional></optional> )
27266 <returnvalue>record</returnvalue>
27267 ( <parameter>slot_name</parameter> <type>name</type>,
27268 <parameter>lsn</parameter> <type>pg_lsn</type> )
27269 </para>
27270 <para>
27271 Copies an existing logical replication slot
27272 named <parameter>src_slot_name</parameter> to a logical replication
27273 slot named <parameter>dst_slot_name</parameter>, optionally changing
27274 the output plugin and persistence. The copied logical slot starts
27275 from the same <acronym>LSN</acronym> as the source logical slot. Both
27276 <parameter>temporary</parameter> and <parameter>plugin</parameter> are
27277 optional; if they are omitted, the values of the source slot are used.
27278 </para></entry>
27279 </row>
27281 <row>
27282 <entry role="func_table_entry"><para role="func_signature">
27283 <indexterm>
27284 <primary>pg_logical_slot_get_changes</primary>
27285 </indexterm>
27286 <function>pg_logical_slot_get_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> )
27287 <returnvalue>setof record</returnvalue>
27288 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27289 <parameter>xid</parameter> <type>xid</type>,
27290 <parameter>data</parameter> <type>text</type> )
27291 </para>
27292 <para>
27293 Returns changes in the slot <parameter>slot_name</parameter>, starting
27294 from the point from which changes have been consumed last. If
27295 <parameter>upto_lsn</parameter>
27296 and <parameter>upto_nchanges</parameter> are NULL,
27297 logical decoding will continue until end of WAL. If
27298 <parameter>upto_lsn</parameter> is non-NULL, decoding will include only
27299 those transactions which commit prior to the specified LSN. If
27300 <parameter>upto_nchanges</parameter> is non-NULL, decoding will
27301 stop when the number of rows produced by decoding exceeds
27302 the specified value. Note, however, that the actual number of
27303 rows returned may be larger, since this limit is only checked after
27304 adding the rows produced when decoding each new transaction commit.
27305 </para></entry>
27306 </row>
27308 <row>
27309 <entry role="func_table_entry"><para role="func_signature">
27310 <indexterm>
27311 <primary>pg_logical_slot_peek_changes</primary>
27312 </indexterm>
27313 <function>pg_logical_slot_peek_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> )
27314 <returnvalue>setof record</returnvalue>
27315 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27316 <parameter>xid</parameter> <type>xid</type>,
27317 <parameter>data</parameter> <type>text</type> )
27318 </para>
27319 <para>
27320 Behaves just like
27321 the <function>pg_logical_slot_get_changes()</function> function,
27322 except that changes are not consumed; that is, they will be returned
27323 again on future calls.
27324 </para></entry>
27325 </row>
27327 <row>
27328 <entry role="func_table_entry"><para role="func_signature">
27329 <indexterm>
27330 <primary>pg_logical_slot_get_binary_changes</primary>
27331 </indexterm>
27332 <function>pg_logical_slot_get_binary_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> )
27333 <returnvalue>setof record</returnvalue>
27334 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27335 <parameter>xid</parameter> <type>xid</type>,
27336 <parameter>data</parameter> <type>bytea</type> )
27337 </para>
27338 <para>
27339 Behaves just like
27340 the <function>pg_logical_slot_get_changes()</function> function,
27341 except that changes are returned as <type>bytea</type>.
27342 </para></entry>
27343 </row>
27345 <row>
27346 <entry role="func_table_entry"><para role="func_signature">
27347 <indexterm>
27348 <primary>pg_logical_slot_peek_binary_changes</primary>
27349 </indexterm>
27350 <function>pg_logical_slot_peek_binary_changes</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type>, <parameter>upto_nchanges</parameter> <type>integer</type>, <literal>VARIADIC</literal> <parameter>options</parameter> <type>text[]</type> )
27351 <returnvalue>setof record</returnvalue>
27352 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27353 <parameter>xid</parameter> <type>xid</type>,
27354 <parameter>data</parameter> <type>bytea</type> )
27355 </para>
27356 <para>
27357 Behaves just like
27358 the <function>pg_logical_slot_peek_changes()</function> function,
27359 except that changes are returned as <type>bytea</type>.
27360 </para></entry>
27361 </row>
27363 <row>
27364 <entry role="func_table_entry"><para role="func_signature">
27365 <indexterm>
27366 <primary>pg_replication_slot_advance</primary>
27367 </indexterm>
27368 <function>pg_replication_slot_advance</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type> )
27369 <returnvalue>record</returnvalue>
27370 ( <parameter>slot_name</parameter> <type>name</type>,
27371 <parameter>end_lsn</parameter> <type>pg_lsn</type> )
27372 </para>
27373 <para>
27374 Advances the current confirmed position of a replication slot named
27375 <parameter>slot_name</parameter>. The slot will not be moved backwards,
27376 and it will not be moved beyond the current insert location. Returns
27377 the name of the slot and the actual position that it was advanced to.
27378 The updated slot position information is written out at the next
27379 checkpoint if any advancing is done. So in the event of a crash, the
27380 slot may return to an earlier position.
27381 </para></entry>
27382 </row>
27384 <row>
27385 <entry id="pg-replication-origin-create" role="func_table_entry"><para role="func_signature">
27386 <indexterm>
27387 <primary>pg_replication_origin_create</primary>
27388 </indexterm>
27389 <function>pg_replication_origin_create</function> ( <parameter>node_name</parameter> <type>text</type> )
27390 <returnvalue>oid</returnvalue>
27391 </para>
27392 <para>
27393 Creates a replication origin with the given external
27394 name, and returns the internal ID assigned to it.
27395 </para></entry>
27396 </row>
27398 <row>
27399 <entry id="pg-replication-origin-drop" role="func_table_entry"><para role="func_signature">
27400 <indexterm>
27401 <primary>pg_replication_origin_drop</primary>
27402 </indexterm>
27403 <function>pg_replication_origin_drop</function> ( <parameter>node_name</parameter> <type>text</type> )
27404 <returnvalue>void</returnvalue>
27405 </para>
27406 <para>
27407 Deletes a previously-created replication origin, including any
27408 associated replay progress.
27409 </para></entry>
27410 </row>
27412 <row>
27413 <entry role="func_table_entry"><para role="func_signature">
27414 <indexterm>
27415 <primary>pg_replication_origin_oid</primary>
27416 </indexterm>
27417 <function>pg_replication_origin_oid</function> ( <parameter>node_name</parameter> <type>text</type> )
27418 <returnvalue>oid</returnvalue>
27419 </para>
27420 <para>
27421 Looks up a replication origin by name and returns the internal ID. If
27422 no such replication origin is found, <literal>NULL</literal> is
27423 returned.
27424 </para></entry>
27425 </row>
27427 <row>
27428 <entry id="pg-replication-origin-session-setup" role="func_table_entry"><para role="func_signature">
27429 <indexterm>
27430 <primary>pg_replication_origin_session_setup</primary>
27431 </indexterm>
27432 <function>pg_replication_origin_session_setup</function> ( <parameter>node_name</parameter> <type>text</type> )
27433 <returnvalue>void</returnvalue>
27434 </para>
27435 <para>
27436 Marks the current session as replaying from the given
27437 origin, allowing replay progress to be tracked.
27438 Can only be used if no origin is currently selected.
27439 Use <function>pg_replication_origin_session_reset</function> to undo.
27440 </para></entry>
27441 </row>
27443 <row>
27444 <entry role="func_table_entry"><para role="func_signature">
27445 <indexterm>
27446 <primary>pg_replication_origin_session_reset</primary>
27447 </indexterm>
27448 <function>pg_replication_origin_session_reset</function> ()
27449 <returnvalue>void</returnvalue>
27450 </para>
27451 <para>
27452 Cancels the effects
27453 of <function>pg_replication_origin_session_setup()</function>.
27454 </para></entry>
27455 </row>
27457 <row>
27458 <entry role="func_table_entry"><para role="func_signature">
27459 <indexterm>
27460 <primary>pg_replication_origin_session_is_setup</primary>
27461 </indexterm>
27462 <function>pg_replication_origin_session_is_setup</function> ()
27463 <returnvalue>boolean</returnvalue>
27464 </para>
27465 <para>
27466 Returns true if a replication origin has been selected in the
27467 current session.
27468 </para></entry>
27469 </row>
27471 <row>
27472 <entry id="pg-replication-origin-session-progress" role="func_table_entry"><para role="func_signature">
27473 <indexterm>
27474 <primary>pg_replication_origin_session_progress</primary>
27475 </indexterm>
27476 <function>pg_replication_origin_session_progress</function> ( <parameter>flush</parameter> <type>boolean</type> )
27477 <returnvalue>pg_lsn</returnvalue>
27478 </para>
27479 <para>
27480 Returns the replay location for the replication origin selected in
27481 the current session. The parameter <parameter>flush</parameter>
27482 determines whether the corresponding local transaction will be
27483 guaranteed to have been flushed to disk or not.
27484 </para></entry>
27485 </row>
27487 <row>
27488 <entry id="pg-replication-origin-xact-setup" role="func_table_entry"><para role="func_signature">
27489 <indexterm>
27490 <primary>pg_replication_origin_xact_setup</primary>
27491 </indexterm>
27492 <function>pg_replication_origin_xact_setup</function> ( <parameter>origin_lsn</parameter> <type>pg_lsn</type>, <parameter>origin_timestamp</parameter> <type>timestamp with time zone</type> )
27493 <returnvalue>void</returnvalue>
27494 </para>
27495 <para>
27496 Marks the current transaction as replaying a transaction that has
27497 committed at the given <acronym>LSN</acronym> and timestamp. Can
27498 only be called when a replication origin has been selected
27499 using <function>pg_replication_origin_session_setup</function>.
27500 </para></entry>
27501 </row>
27503 <row>
27504 <entry id="pg-replication-origin-xact-reset" role="func_table_entry"><para role="func_signature">
27505 <indexterm>
27506 <primary>pg_replication_origin_xact_reset</primary>
27507 </indexterm>
27508 <function>pg_replication_origin_xact_reset</function> ()
27509 <returnvalue>void</returnvalue>
27510 </para>
27511 <para>
27512 Cancels the effects of
27513 <function>pg_replication_origin_xact_setup()</function>.
27514 </para></entry>
27515 </row>
27517 <row>
27518 <entry id="pg-replication-origin-advance" role="func_table_entry"><para role="func_signature">
27519 <indexterm>
27520 <primary>pg_replication_origin_advance</primary>
27521 </indexterm>
27522 <function>pg_replication_origin_advance</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>lsn</parameter> <type>pg_lsn</type> )
27523 <returnvalue>void</returnvalue>
27524 </para>
27525 <para>
27526 Sets replication progress for the given node to the given
27527 location. This is primarily useful for setting up the initial
27528 location, or setting a new location after configuration changes and
27529 similar. Be aware that careless use of this function can lead to
27530 inconsistently replicated data.
27531 </para></entry>
27532 </row>
27534 <row>
27535 <entry id="pg-replication-origin-progress" role="func_table_entry"><para role="func_signature">
27536 <indexterm>
27537 <primary>pg_replication_origin_progress</primary>
27538 </indexterm>
27539 <function>pg_replication_origin_progress</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>boolean</type> )
27540 <returnvalue>pg_lsn</returnvalue>
27541 </para>
27542 <para>
27543 Returns the replay location for the given replication origin. The
27544 parameter <parameter>flush</parameter> determines whether the
27545 corresponding local transaction will be guaranteed to have been
27546 flushed to disk or not.
27547 </para></entry>
27548 </row>
27550 <row>
27551 <entry id="pg-logical-emit-message" role="func_table_entry"><para role="func_signature">
27552 <indexterm>
27553 <primary>pg_logical_emit_message</primary>
27554 </indexterm>
27555 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>text</type> )
27556 <returnvalue>pg_lsn</returnvalue>
27557 </para>
27558 <para role="func_signature">
27559 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>bytea</type> )
27560 <returnvalue>pg_lsn</returnvalue>
27561 </para>
27562 <para>
27563 Emits a logical decoding message. This can be used to pass generic
27564 messages to logical decoding plugins through
27565 WAL. The <parameter>transactional</parameter> parameter specifies if
27566 the message should be part of the current transaction, or if it should
27567 be written immediately and decoded as soon as the logical decoder
27568 reads the record. The <parameter>prefix</parameter> parameter is a
27569 textual prefix that can be used by logical decoding plugins to easily
27570 recognize messages that are interesting for them.
27571 The <parameter>content</parameter> parameter is the content of the
27572 message, given either in text or binary form.
27573 </para></entry>
27574 </row>
27575 </tbody>
27576 </tgroup>
27577 </table>
27579 </sect2>
27581 <sect2 id="functions-admin-dbobject">
27582 <title>Database Object Management Functions</title>
27584 <para>
27585 The functions shown in <xref linkend="functions-admin-dbsize"/> calculate
27586 the disk space usage of database objects, or assist in presentation
27587 or understanding of usage results. <literal>bigint</literal> results
27588 are measured in bytes. If an OID that does
27589 not represent an existing object is passed to one of these
27590 functions, <literal>NULL</literal> is returned.
27591 </para>
27593 <table id="functions-admin-dbsize">
27594 <title>Database Object Size Functions</title>
27595 <tgroup cols="1">
27596 <thead>
27597 <row>
27598 <entry role="func_table_entry"><para role="func_signature">
27599 Function
27600 </para>
27601 <para>
27602 Description
27603 </para></entry>
27604 </row>
27605 </thead>
27607 <tbody>
27608 <row>
27609 <entry role="func_table_entry"><para role="func_signature">
27610 <indexterm>
27611 <primary>pg_column_size</primary>
27612 </indexterm>
27613 <function>pg_column_size</function> ( <type>"any"</type> )
27614 <returnvalue>integer</returnvalue>
27615 </para>
27616 <para>
27617 Shows the number of bytes used to store any individual data value. If
27618 applied directly to a table column value, this reflects any
27619 compression that was done.
27620 </para></entry>
27621 </row>
27623 <row>
27624 <entry role="func_table_entry"><para role="func_signature">
27625 <indexterm>
27626 <primary>pg_column_compression</primary>
27627 </indexterm>
27628 <function>pg_column_compression</function> ( <type>"any"</type> )
27629 <returnvalue>text</returnvalue>
27630 </para>
27631 <para>
27632 Shows the compression algorithm that was used to compress
27633 an individual variable-length value. Returns <literal>NULL</literal>
27634 if the value is not compressed.
27635 </para></entry>
27636 </row>
27638 <row>
27639 <entry role="func_table_entry"><para role="func_signature">
27640 <indexterm>
27641 <primary>pg_database_size</primary>
27642 </indexterm>
27643 <function>pg_database_size</function> ( <type>name</type> )
27644 <returnvalue>bigint</returnvalue>
27645 </para>
27646 <para role="func_signature">
27647 <function>pg_database_size</function> ( <type>oid</type> )
27648 <returnvalue>bigint</returnvalue>
27649 </para>
27650 <para>
27651 Computes the total disk space used by the database with the specified
27652 name or OID. To use this function, you must
27653 have <literal>CONNECT</literal> privilege on the specified database
27654 (which is granted by default) or have privileges of
27655 the <literal>pg_read_all_stats</literal> role.
27656 </para></entry>
27657 </row>
27659 <row>
27660 <entry role="func_table_entry"><para role="func_signature">
27661 <indexterm>
27662 <primary>pg_indexes_size</primary>
27663 </indexterm>
27664 <function>pg_indexes_size</function> ( <type>regclass</type> )
27665 <returnvalue>bigint</returnvalue>
27666 </para>
27667 <para>
27668 Computes the total disk space used by indexes attached to the
27669 specified table.
27670 </para></entry>
27671 </row>
27673 <row>
27674 <entry role="func_table_entry"><para role="func_signature">
27675 <indexterm>
27676 <primary>pg_relation_size</primary>
27677 </indexterm>
27678 <function>pg_relation_size</function> ( <parameter>relation</parameter> <type>regclass</type> <optional>, <parameter>fork</parameter> <type>text</type> </optional> )
27679 <returnvalue>bigint</returnvalue>
27680 </para>
27681 <para>
27682 Computes the disk space used by one <quote>fork</quote> of the
27683 specified relation. (Note that for most purposes it is more
27684 convenient to use the higher-level
27685 functions <function>pg_total_relation_size</function>
27686 or <function>pg_table_size</function>, which sum the sizes of all
27687 forks.) With one argument, this returns the size of the main data
27688 fork of the relation. The second argument can be provided to specify
27689 which fork to examine:
27690 <itemizedlist spacing="compact">
27691 <listitem>
27692 <para>
27693 <literal>main</literal> returns the size of the main
27694 data fork of the relation.
27695 </para>
27696 </listitem>
27697 <listitem>
27698 <para>
27699 <literal>fsm</literal> returns the size of the Free Space Map
27700 (see <xref linkend="storage-fsm"/>) associated with the relation.
27701 </para>
27702 </listitem>
27703 <listitem>
27704 <para>
27705 <literal>vm</literal> returns the size of the Visibility Map
27706 (see <xref linkend="storage-vm"/>) associated with the relation.
27707 </para>
27708 </listitem>
27709 <listitem>
27710 <para>
27711 <literal>init</literal> returns the size of the initialization
27712 fork, if any, associated with the relation.
27713 </para>
27714 </listitem>
27715 </itemizedlist>
27716 </para></entry>
27717 </row>
27719 <row>
27720 <entry role="func_table_entry"><para role="func_signature">
27721 <indexterm>
27722 <primary>pg_size_bytes</primary>
27723 </indexterm>
27724 <function>pg_size_bytes</function> ( <type>text</type> )
27725 <returnvalue>bigint</returnvalue>
27726 </para>
27727 <para>
27728 Converts a size in human-readable format (as returned
27729 by <function>pg_size_pretty</function>) into bytes. Valid units are
27730 <literal>bytes</literal>, <literal>B</literal>, <literal>kB</literal>,
27731 <literal>MB</literal>, <literal>GB</literal>, <literal>TB</literal>,
27732 and <literal>PB</literal>.
27733 </para></entry>
27734 </row>
27736 <row>
27737 <entry role="func_table_entry"><para role="func_signature">
27738 <indexterm>
27739 <primary>pg_size_pretty</primary>
27740 </indexterm>
27741 <function>pg_size_pretty</function> ( <type>bigint</type> )
27742 <returnvalue>text</returnvalue>
27743 </para>
27744 <para role="func_signature">
27745 <function>pg_size_pretty</function> ( <type>numeric</type> )
27746 <returnvalue>text</returnvalue>
27747 </para>
27748 <para>
27749 Converts a size in bytes into a more easily human-readable format with
27750 size units (bytes, kB, MB, GB, TB, or PB as appropriate). Note that the
27751 units are powers of 2 rather than powers of 10, so 1kB is 1024 bytes,
27752 1MB is 1024<superscript>2</superscript> = 1048576 bytes, and so on.
27753 </para></entry>
27754 </row>
27756 <row>
27757 <entry role="func_table_entry"><para role="func_signature">
27758 <indexterm>
27759 <primary>pg_table_size</primary>
27760 </indexterm>
27761 <function>pg_table_size</function> ( <type>regclass</type> )
27762 <returnvalue>bigint</returnvalue>
27763 </para>
27764 <para>
27765 Computes the disk space used by the specified table, excluding indexes
27766 (but including its TOAST table if any, free space map, and visibility
27767 map).
27768 </para></entry>
27769 </row>
27771 <row>
27772 <entry role="func_table_entry"><para role="func_signature">
27773 <indexterm>
27774 <primary>pg_tablespace_size</primary>
27775 </indexterm>
27776 <function>pg_tablespace_size</function> ( <type>name</type> )
27777 <returnvalue>bigint</returnvalue>
27778 </para>
27779 <para role="func_signature">
27780 <function>pg_tablespace_size</function> ( <type>oid</type> )
27781 <returnvalue>bigint</returnvalue>
27782 </para>
27783 <para>
27784 Computes the total disk space used in the tablespace with the
27785 specified name or OID. To use this function, you must
27786 have <literal>CREATE</literal> privilege on the specified tablespace
27787 or have privileges of the <literal>pg_read_all_stats</literal> role,
27788 unless it is the default tablespace for the current database.
27789 </para></entry>
27790 </row>
27792 <row>
27793 <entry role="func_table_entry"><para role="func_signature">
27794 <indexterm>
27795 <primary>pg_total_relation_size</primary>
27796 </indexterm>
27797 <function>pg_total_relation_size</function> ( <type>regclass</type> )
27798 <returnvalue>bigint</returnvalue>
27799 </para>
27800 <para>
27801 Computes the total disk space used by the specified table, including
27802 all indexes and <acronym>TOAST</acronym> data. The result is
27803 equivalent to <function>pg_table_size</function>
27804 <literal>+</literal> <function>pg_indexes_size</function>.
27805 </para></entry>
27806 </row>
27807 </tbody>
27808 </tgroup>
27809 </table>
27811 <para>
27812 The functions above that operate on tables or indexes accept a
27813 <type>regclass</type> argument, which is simply the OID of the table or index
27814 in the <structname>pg_class</structname> system catalog. You do not have to look up
27815 the OID by hand, however, since the <type>regclass</type> data type's input
27816 converter will do the work for you. See <xref linkend="datatype-oid"/>
27817 for details.
27818 </para>
27820 <para>
27821 The functions shown in <xref linkend="functions-admin-dblocation"/> assist
27822 in identifying the specific disk files associated with database objects.
27823 </para>
27825 <table id="functions-admin-dblocation">
27826 <title>Database Object Location Functions</title>
27827 <tgroup cols="1">
27828 <thead>
27829 <row>
27830 <entry role="func_table_entry"><para role="func_signature">
27831 Function
27832 </para>
27833 <para>
27834 Description
27835 </para></entry>
27836 </row>
27837 </thead>
27839 <tbody>
27840 <row>
27841 <entry role="func_table_entry"><para role="func_signature">
27842 <indexterm>
27843 <primary>pg_relation_filenode</primary>
27844 </indexterm>
27845 <function>pg_relation_filenode</function> ( <parameter>relation</parameter> <type>regclass</type> )
27846 <returnvalue>oid</returnvalue>
27847 </para>
27848 <para>
27849 Returns the <quote>filenode</quote> number currently assigned to the
27850 specified relation. The filenode is the base component of the file
27851 name(s) used for the relation (see
27852 <xref linkend="storage-file-layout"/> for more information).
27853 For most relations the result is the same as
27854 <structname>pg_class</structname>.<structfield>relfilenode</structfield>,
27855 but for certain system catalogs <structfield>relfilenode</structfield>
27856 is zero and this function must be used to get the correct value. The
27857 function returns NULL if passed a relation that does not have storage,
27858 such as a view.
27859 </para></entry>
27860 </row>
27862 <row>
27863 <entry role="func_table_entry"><para role="func_signature">
27864 <indexterm>
27865 <primary>pg_relation_filepath</primary>
27866 </indexterm>
27867 <function>pg_relation_filepath</function> ( <parameter>relation</parameter> <type>regclass</type> )
27868 <returnvalue>text</returnvalue>
27869 </para>
27870 <para>
27871 Returns the entire file path name (relative to the database cluster's
27872 data directory, <varname>PGDATA</varname>) of the relation.
27873 </para></entry>
27874 </row>
27876 <row>
27877 <entry role="func_table_entry"><para role="func_signature">
27878 <indexterm>
27879 <primary>pg_filenode_relation</primary>
27880 </indexterm>
27881 <function>pg_filenode_relation</function> ( <parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type> )
27882 <returnvalue>regclass</returnvalue>
27883 </para>
27884 <para>
27885 Returns a relation's OID given the tablespace OID and filenode it is
27886 stored under. This is essentially the inverse mapping of
27887 <function>pg_relation_filepath</function>. For a relation in the
27888 database's default tablespace, the tablespace can be specified as zero.
27889 Returns <literal>NULL</literal> if no relation in the current database
27890 is associated with the given values.
27891 </para></entry>
27892 </row>
27893 </tbody>
27894 </tgroup>
27895 </table>
27897 <para>
27898 <xref linkend="functions-admin-collation"/> lists functions used to manage
27899 collations.
27900 </para>
27902 <table id="functions-admin-collation">
27903 <title>Collation Management Functions</title>
27904 <tgroup cols="1">
27905 <thead>
27906 <row>
27907 <entry role="func_table_entry"><para role="func_signature">
27908 Function
27909 </para>
27910 <para>
27911 Description
27912 </para></entry>
27913 </row>
27914 </thead>
27916 <tbody>
27917 <row>
27918 <entry role="func_table_entry"><para role="func_signature">
27919 <indexterm>
27920 <primary>pg_collation_actual_version</primary>
27921 </indexterm>
27922 <function>pg_collation_actual_version</function> ( <type>oid</type> )
27923 <returnvalue>text</returnvalue>
27924 </para>
27925 <para>
27926 Returns the actual version of the collation object as it is currently
27927 installed in the operating system. If this is different from the
27928 value in
27929 <structname>pg_collation</structname>.<structfield>collversion</structfield>,
27930 then objects depending on the collation might need to be rebuilt. See
27931 also <xref linkend="sql-altercollation"/>.
27932 </para></entry>
27933 </row>
27935 <row>
27936 <entry role="func_table_entry"><para role="func_signature">
27937 <indexterm>
27938 <primary>pg_database_collation_actual_version</primary>
27939 </indexterm>
27940 <function>pg_database_collation_actual_version</function> ( <type>oid</type> )
27941 <returnvalue>text</returnvalue>
27942 </para>
27943 <para>
27944 Returns the actual version of the database's collation as it is currently
27945 installed in the operating system. If this is different from the
27946 value in
27947 <structname>pg_database</structname>.<structfield>datcollversion</structfield>,
27948 then objects depending on the collation might need to be rebuilt. See
27949 also <xref linkend="sql-alterdatabase"/>.
27950 </para></entry>
27951 </row>
27953 <row>
27954 <entry role="func_table_entry"><para role="func_signature">
27955 <indexterm>
27956 <primary>pg_import_system_collations</primary>
27957 </indexterm>
27958 <function>pg_import_system_collations</function> ( <parameter>schema</parameter> <type>regnamespace</type> )
27959 <returnvalue>integer</returnvalue>
27960 </para>
27961 <para>
27962 Adds collations to the system
27963 catalog <structname>pg_collation</structname> based on all the locales
27964 it finds in the operating system. This is
27965 what <command>initdb</command> uses; see
27966 <xref linkend="collation-managing"/> for more details. If additional
27967 locales are installed into the operating system later on, this
27968 function can be run again to add collations for the new locales.
27969 Locales that match existing entries
27970 in <structname>pg_collation</structname> will be skipped. (But
27971 collation objects based on locales that are no longer present in the
27972 operating system are not removed by this function.)
27973 The <parameter>schema</parameter> parameter would typically
27974 be <literal>pg_catalog</literal>, but that is not a requirement; the
27975 collations could be installed into some other schema as well. The
27976 function returns the number of new collation objects it created.
27977 Use of this function is restricted to superusers.
27978 </para></entry>
27979 </row>
27980 </tbody>
27981 </tgroup>
27982 </table>
27984 <para>
27985 <xref linkend="functions-info-partition"/> lists functions that provide
27986 information about the structure of partitioned tables.
27987 </para>
27989 <table id="functions-info-partition">
27990 <title>Partitioning Information Functions</title>
27991 <tgroup cols="1">
27992 <thead>
27993 <row>
27994 <entry role="func_table_entry"><para role="func_signature">
27995 Function
27996 </para>
27997 <para>
27998 Description
27999 </para></entry>
28000 </row>
28001 </thead>
28003 <tbody>
28004 <row>
28005 <entry role="func_table_entry"><para role="func_signature">
28006 <indexterm>
28007 <primary>pg_partition_tree</primary>
28008 </indexterm>
28009 <function>pg_partition_tree</function> ( <type>regclass</type> )
28010 <returnvalue>setof record</returnvalue>
28011 ( <parameter>relid</parameter> <type>regclass</type>,
28012 <parameter>parentrelid</parameter> <type>regclass</type>,
28013 <parameter>isleaf</parameter> <type>boolean</type>,
28014 <parameter>level</parameter> <type>integer</type> )
28015 </para>
28016 <para>
28017 Lists the tables or indexes in the partition tree of the
28018 given partitioned table or partitioned index, with one row for each
28019 partition. Information provided includes the OID of the partition,
28020 the OID of its immediate parent, a boolean value telling if the
28021 partition is a leaf, and an integer telling its level in the hierarchy.
28022 The level value is 0 for the input table or index, 1 for its
28023 immediate child partitions, 2 for their partitions, and so on.
28024 Returns no rows if the relation does not exist or is not a partition
28025 or partitioned table.
28026 </para></entry>
28027 </row>
28029 <row>
28030 <entry role="func_table_entry"><para role="func_signature">
28031 <indexterm>
28032 <primary>pg_partition_ancestors</primary>
28033 </indexterm>
28034 <function>pg_partition_ancestors</function> ( <type>regclass</type> )
28035 <returnvalue>setof regclass</returnvalue>
28036 </para>
28037 <para>
28038 Lists the ancestor relations of the given partition,
28039 including the relation itself. Returns no rows if the relation
28040 does not exist or is not a partition or partitioned table.
28041 </para></entry>
28042 </row>
28044 <row>
28045 <entry role="func_table_entry"><para role="func_signature">
28046 <indexterm>
28047 <primary>pg_partition_root</primary>
28048 </indexterm>
28049 <function>pg_partition_root</function> ( <type>regclass</type> )
28050 <returnvalue>regclass</returnvalue>
28051 </para>
28052 <para>
28053 Returns the top-most parent of the partition tree to which the given
28054 relation belongs. Returns <literal>NULL</literal> if the relation
28055 does not exist or is not a partition or partitioned table.
28056 </para></entry>
28057 </row>
28058 </tbody>
28059 </tgroup>
28060 </table>
28062 <para>
28063 For example, to check the total size of the data contained in a
28064 partitioned table <structname>measurement</structname>, one could use the
28065 following query:
28066 <programlisting>
28067 SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
28068 FROM pg_partition_tree('measurement');
28069 </programlisting>
28070 </para>
28072 </sect2>
28074 <sect2 id="functions-admin-index">
28075 <title>Index Maintenance Functions</title>
28077 <para>
28078 <xref linkend="functions-admin-index-table"/> shows the functions
28079 available for index maintenance tasks. (Note that these maintenance
28080 tasks are normally done automatically by autovacuum; use of these
28081 functions is only required in special cases.)
28082 These functions cannot be executed during recovery.
28083 Use of these functions is restricted to superusers and the owner
28084 of the given index.
28085 </para>
28087 <table id="functions-admin-index-table">
28088 <title>Index Maintenance Functions</title>
28089 <tgroup cols="1">
28090 <thead>
28091 <row>
28092 <entry role="func_table_entry"><para role="func_signature">
28093 Function
28094 </para>
28095 <para>
28096 Description
28097 </para></entry>
28098 </row>
28099 </thead>
28101 <tbody>
28102 <row>
28103 <entry role="func_table_entry"><para role="func_signature">
28104 <indexterm>
28105 <primary>brin_summarize_new_values</primary>
28106 </indexterm>
28107 <function>brin_summarize_new_values</function> ( <parameter>index</parameter> <type>regclass</type> )
28108 <returnvalue>integer</returnvalue>
28109 </para>
28110 <para>
28111 Scans the specified BRIN index to find page ranges in the base table
28112 that are not currently summarized by the index; for any such range it
28113 creates a new summary index tuple by scanning those table pages.
28114 Returns the number of new page range summaries that were inserted
28115 into the index.
28116 </para></entry>
28117 </row>
28119 <row>
28120 <entry role="func_table_entry"><para role="func_signature">
28121 <indexterm>
28122 <primary>brin_summarize_range</primary>
28123 </indexterm>
28124 <function>brin_summarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
28125 <returnvalue>integer</returnvalue>
28126 </para>
28127 <para>
28128 Summarizes the page range covering the given block, if not already
28129 summarized. This is
28130 like <function>brin_summarize_new_values</function> except that it
28131 only processes the page range that covers the given table block number.
28132 </para></entry>
28133 </row>
28135 <row>
28136 <entry role="func_table_entry"><para role="func_signature">
28137 <indexterm>
28138 <primary>brin_desummarize_range</primary>
28139 </indexterm>
28140 <function>brin_desummarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
28141 <returnvalue>void</returnvalue>
28142 </para>
28143 <para>
28144 Removes the BRIN index tuple that summarizes the page range covering
28145 the given table block, if there is one.
28146 </para></entry>
28147 </row>
28149 <row>
28150 <entry role="func_table_entry"><para role="func_signature">
28151 <indexterm>
28152 <primary>gin_clean_pending_list</primary>
28153 </indexterm>
28154 <function>gin_clean_pending_list</function> ( <parameter>index</parameter> <type>regclass</type> )
28155 <returnvalue>bigint</returnvalue>
28156 </para>
28157 <para>
28158 Cleans up the <quote>pending</quote> list of the specified GIN index
28159 by moving entries in it, in bulk, to the main GIN data structure.
28160 Returns the number of pages removed from the pending list.
28161 If the argument is a GIN index built with
28162 the <literal>fastupdate</literal> option disabled, no cleanup happens
28163 and the result is zero, because the index doesn't have a pending list.
28164 See <xref linkend="gin-fast-update"/> and <xref linkend="gin-tips"/>
28165 for details about the pending list and <literal>fastupdate</literal>
28166 option.
28167 </para></entry>
28168 </row>
28169 </tbody>
28170 </tgroup>
28171 </table>
28173 </sect2>
28175 <sect2 id="functions-admin-genfile">
28176 <title>Generic File Access Functions</title>
28178 <para>
28179 The functions shown in <xref
28180 linkend="functions-admin-genfile-table"/> provide native access to
28181 files on the machine hosting the server. Only files within the
28182 database cluster directory and the <varname>log_directory</varname> can be
28183 accessed, unless the user is a superuser or is granted the role
28184 <literal>pg_read_server_files</literal>. Use a relative path for files in
28185 the cluster directory, and a path matching the <varname>log_directory</varname>
28186 configuration setting for log files.
28187 </para>
28189 <para>
28190 Note that granting users the EXECUTE privilege on
28191 <function>pg_read_file()</function>, or related functions, allows them the
28192 ability to read any file on the server that the database server process can
28193 read; these functions bypass all in-database privilege checks. This means
28194 that, for example, a user with such access is able to read the contents of
28195 the <structname>pg_authid</structname> table where authentication
28196 information is stored, as well as read any table data in the database.
28197 Therefore, granting access to these functions should be carefully
28198 considered.
28199 </para>
28201 <para>
28202 When granting privilege on these functions, note that the table entries
28203 showing optional parameters are mostly implemented as several physical
28204 functions with different parameter lists. Privilege must be granted
28205 separately on each such function, if it is to be
28206 used. <application>psql</application>'s <command>\df</command> command
28207 can be useful to check what the actual function signatures are.
28208 </para>
28210 <para>
28211 Some of these functions take an optional <parameter>missing_ok</parameter>
28212 parameter, which specifies the behavior when the file or directory does
28213 not exist. If <literal>true</literal>, the function
28214 returns <literal>NULL</literal> or an empty result set, as appropriate.
28215 If <literal>false</literal>, an error is raised. (Failure conditions
28216 other than <quote>file not found</quote> are reported as errors in any
28217 case.) The default is <literal>false</literal>.
28218 </para>
28220 <table id="functions-admin-genfile-table">
28221 <title>Generic File Access Functions</title>
28222 <tgroup cols="1">
28223 <thead>
28224 <row>
28225 <entry role="func_table_entry"><para role="func_signature">
28226 Function
28227 </para>
28228 <para>
28229 Description
28230 </para></entry>
28231 </row>
28232 </thead>
28234 <tbody>
28235 <row>
28236 <entry role="func_table_entry"><para role="func_signature">
28237 <indexterm>
28238 <primary>pg_ls_dir</primary>
28239 </indexterm>
28240 <function>pg_ls_dir</function> ( <parameter>dirname</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type>, <parameter>include_dot_dirs</parameter> <type>boolean</type> </optional> )
28241 <returnvalue>setof text</returnvalue>
28242 </para>
28243 <para>
28244 Returns the names of all files (and directories and other special
28245 files) in the specified
28246 directory. The <parameter>include_dot_dirs</parameter> parameter
28247 indicates whether <quote>.</quote> and <quote>..</quote> are to be
28248 included in the result set; the default is to exclude them. Including
28249 them can be useful when <parameter>missing_ok</parameter>
28250 is <literal>true</literal>, to distinguish an empty directory from a
28251 non-existent directory.
28252 </para>
28253 <para>
28254 This function is restricted to superusers by default, but other users
28255 can be granted EXECUTE to run the function.
28256 </para></entry>
28257 </row>
28259 <row>
28260 <entry role="func_table_entry"><para role="func_signature">
28261 <indexterm>
28262 <primary>pg_ls_logdir</primary>
28263 </indexterm>
28264 <function>pg_ls_logdir</function> ()
28265 <returnvalue>setof record</returnvalue>
28266 ( <parameter>name</parameter> <type>text</type>,
28267 <parameter>size</parameter> <type>bigint</type>,
28268 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28269 </para>
28270 <para>
28271 Returns the name, size, and last modification time (mtime) of each
28272 ordinary file in the server's log directory. Filenames beginning with
28273 a dot, directories, and other special files are excluded.
28274 </para>
28275 <para>
28276 This function is restricted to superusers and roles with privileges of
28277 the <literal>pg_monitor</literal> role by default, but other users can
28278 be granted EXECUTE to run the function.
28279 </para></entry>
28280 </row>
28282 <row>
28283 <entry role="func_table_entry"><para role="func_signature">
28284 <indexterm>
28285 <primary>pg_ls_waldir</primary>
28286 </indexterm>
28287 <function>pg_ls_waldir</function> ()
28288 <returnvalue>setof record</returnvalue>
28289 ( <parameter>name</parameter> <type>text</type>,
28290 <parameter>size</parameter> <type>bigint</type>,
28291 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28292 </para>
28293 <para>
28294 Returns the name, size, and last modification time (mtime) of each
28295 ordinary file in the server's write-ahead log (WAL) directory.
28296 Filenames beginning with a dot, directories, and other special files
28297 are excluded.
28298 </para>
28299 <para>
28300 This function is restricted to superusers and roles with privileges of
28301 the <literal>pg_monitor</literal> role by default, but other users can
28302 be granted EXECUTE to run the function.
28303 </para></entry>
28304 </row>
28306 <row>
28307 <entry role="func_table_entry"><para role="func_signature">
28308 <indexterm>
28309 <primary>pg_ls_logicalmapdir</primary>
28310 </indexterm>
28311 <function>pg_ls_logicalmapdir</function> ()
28312 <returnvalue>setof record</returnvalue>
28313 ( <parameter>name</parameter> <type>text</type>,
28314 <parameter>size</parameter> <type>bigint</type>,
28315 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28316 </para>
28317 <para>
28318 Returns the name, size, and last modification time (mtime) of each
28319 ordinary file in the server's <filename>pg_logical/mappings</filename>
28320 directory. Filenames beginning with a dot, directories, and other
28321 special files are excluded.
28322 </para>
28323 <para>
28324 This function is restricted to superusers and members of
28325 the <literal>pg_monitor</literal> role by default, but other users can
28326 be granted EXECUTE to run the function.
28327 </para></entry>
28328 </row>
28330 <row>
28331 <entry role="func_table_entry"><para role="func_signature">
28332 <indexterm>
28333 <primary>pg_ls_logicalsnapdir</primary>
28334 </indexterm>
28335 <function>pg_ls_logicalsnapdir</function> ()
28336 <returnvalue>setof record</returnvalue>
28337 ( <parameter>name</parameter> <type>text</type>,
28338 <parameter>size</parameter> <type>bigint</type>,
28339 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28340 </para>
28341 <para>
28342 Returns the name, size, and last modification time (mtime) of each
28343 ordinary file in the server's <filename>pg_logical/snapshots</filename>
28344 directory. Filenames beginning with a dot, directories, and other
28345 special files are excluded.
28346 </para>
28347 <para>
28348 This function is restricted to superusers and members of
28349 the <literal>pg_monitor</literal> role by default, but other users can
28350 be granted EXECUTE to run the function.
28351 </para></entry>
28352 </row>
28354 <row>
28355 <entry role="func_table_entry"><para role="func_signature">
28356 <indexterm>
28357 <primary>pg_ls_replslotdir</primary>
28358 </indexterm>
28359 <function>pg_ls_replslotdir</function> ( <parameter>slot_name</parameter> <type>text</type> )
28360 <returnvalue>setof record</returnvalue>
28361 ( <parameter>name</parameter> <type>text</type>,
28362 <parameter>size</parameter> <type>bigint</type>,
28363 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28364 </para>
28365 <para>
28366 Returns the name, size, and last modification time (mtime) of each
28367 ordinary file in the server's <filename>pg_replslot/slot_name</filename>
28368 directory, where <parameter>slot_name</parameter> is the name of the
28369 replication slot provided as input of the function. Filenames beginning
28370 with a dot, directories, and other special files are excluded.
28371 </para>
28372 <para>
28373 This function is restricted to superusers and members of
28374 the <literal>pg_monitor</literal> role by default, but other users can
28375 be granted EXECUTE to run the function.
28376 </para></entry>
28377 </row>
28379 <row>
28380 <entry role="func_table_entry"><para role="func_signature">
28381 <indexterm>
28382 <primary>pg_ls_archive_statusdir</primary>
28383 </indexterm>
28384 <function>pg_ls_archive_statusdir</function> ()
28385 <returnvalue>setof record</returnvalue>
28386 ( <parameter>name</parameter> <type>text</type>,
28387 <parameter>size</parameter> <type>bigint</type>,
28388 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28389 </para>
28390 <para>
28391 Returns the name, size, and last modification time (mtime) of each
28392 ordinary file in the server's WAL archive status directory
28393 (<filename>pg_wal/archive_status</filename>). Filenames beginning
28394 with a dot, directories, and other special files are excluded.
28395 </para>
28396 <para>
28397 This function is restricted to superusers and members of
28398 the <literal>pg_monitor</literal> role by default, but other users can
28399 be granted EXECUTE to run the function.
28400 </para></entry>
28401 </row>
28403 <row>
28404 <entry role="func_table_entry"><para role="func_signature">
28406 <indexterm>
28407 <primary>pg_ls_tmpdir</primary>
28408 </indexterm>
28409 <function>pg_ls_tmpdir</function> ( <optional> <parameter>tablespace</parameter> <type>oid</type> </optional> )
28410 <returnvalue>setof record</returnvalue>
28411 ( <parameter>name</parameter> <type>text</type>,
28412 <parameter>size</parameter> <type>bigint</type>,
28413 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28414 </para>
28415 <para>
28416 Returns the name, size, and last modification time (mtime) of each
28417 ordinary file in the temporary file directory for the
28418 specified <parameter>tablespace</parameter>.
28419 If <parameter>tablespace</parameter> is not provided,
28420 the <literal>pg_default</literal> tablespace is examined. Filenames
28421 beginning with a dot, directories, and other special files are
28422 excluded.
28423 </para>
28424 <para>
28425 This function is restricted to superusers and members of
28426 the <literal>pg_monitor</literal> role by default, but other users can
28427 be granted EXECUTE to run the function.
28428 </para></entry>
28429 </row>
28431 <row>
28432 <entry role="func_table_entry"><para role="func_signature">
28433 <indexterm>
28434 <primary>pg_read_file</primary>
28435 </indexterm>
28436 <function>pg_read_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>offset</parameter> <type>bigint</type>, <parameter>length</parameter> <type>bigint</type> </optional> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
28437 <returnvalue>text</returnvalue>
28438 </para>
28439 <para>
28440 Returns all or part of a text file, starting at the
28441 given byte <parameter>offset</parameter>, returning at
28442 most <parameter>length</parameter> bytes (less if the end of file is
28443 reached first). If <parameter>offset</parameter> is negative, it is
28444 relative to the end of the file. If <parameter>offset</parameter>
28445 and <parameter>length</parameter> are omitted, the entire file is
28446 returned. The bytes read from the file are interpreted as a string in
28447 the database's encoding; an error is thrown if they are not valid in
28448 that encoding.
28449 </para>
28450 <para>
28451 This function is restricted to superusers by default, but other users
28452 can be granted EXECUTE to run the function.
28453 </para></entry>
28454 </row>
28456 <row>
28457 <entry role="func_table_entry"><para role="func_signature">
28458 <indexterm>
28459 <primary>pg_read_binary_file</primary>
28460 </indexterm>
28461 <function>pg_read_binary_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>offset</parameter> <type>bigint</type>, <parameter>length</parameter> <type>bigint</type> </optional> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
28462 <returnvalue>bytea</returnvalue>
28463 </para>
28464 <para>
28465 Returns all or part of a file. This function is identical to
28466 <function>pg_read_file</function> except that it can read arbitrary
28467 binary data, returning the result as <type>bytea</type>
28468 not <type>text</type>; accordingly, no encoding checks are performed.
28469 </para>
28470 <para>
28471 This function is restricted to superusers by default, but other users
28472 can be granted EXECUTE to run the function.
28473 </para>
28474 <para>
28475 In combination with the <function>convert_from</function> function,
28476 this function can be used to read a text file in a specified encoding
28477 and convert to the database's encoding:
28478 <programlisting>
28479 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
28480 </programlisting>
28481 </para></entry>
28482 </row>
28484 <row>
28485 <entry role="func_table_entry"><para role="func_signature">
28486 <indexterm>
28487 <primary>pg_stat_file</primary>
28488 </indexterm>
28489 <function>pg_stat_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
28490 <returnvalue>record</returnvalue>
28491 ( <parameter>size</parameter> <type>bigint</type>,
28492 <parameter>access</parameter> <type>timestamp with time zone</type>,
28493 <parameter>modification</parameter> <type>timestamp with time zone</type>,
28494 <parameter>change</parameter> <type>timestamp with time zone</type>,
28495 <parameter>creation</parameter> <type>timestamp with time zone</type>,
28496 <parameter>isdir</parameter> <type>boolean</type> )
28497 </para>
28498 <para>
28499 Returns a record containing the file's size, last access time stamp,
28500 last modification time stamp, last file status change time stamp (Unix
28501 platforms only), file creation time stamp (Windows only), and a flag
28502 indicating if it is a directory.
28503 </para>
28504 <para>
28505 This function is restricted to superusers by default, but other users
28506 can be granted EXECUTE to run the function.
28507 </para></entry>
28508 </row>
28510 </tbody>
28511 </tgroup>
28512 </table>
28514 </sect2>
28516 <sect2 id="functions-advisory-locks">
28517 <title>Advisory Lock Functions</title>
28519 <para>
28520 The functions shown in <xref linkend="functions-advisory-locks-table"/>
28521 manage advisory locks. For details about proper use of these functions,
28522 see <xref linkend="advisory-locks"/>.
28523 </para>
28525 <para>
28526 All these functions are intended to be used to lock application-defined
28527 resources, which can be identified either by a single 64-bit key value or
28528 two 32-bit key values (note that these two key spaces do not overlap).
28529 If another session already holds a conflicting lock on the same resource
28530 identifier, the functions will either wait until the resource becomes
28531 available, or return a <literal>false</literal> result, as appropriate for
28532 the function.
28533 Locks can be either shared or exclusive: a shared lock does not conflict
28534 with other shared locks on the same resource, only with exclusive locks.
28535 Locks can be taken at session level (so that they are held until released
28536 or the session ends) or at transaction level (so that they are held until
28537 the current transaction ends; there is no provision for manual release).
28538 Multiple session-level lock requests stack, so that if the same resource
28539 identifier is locked three times there must then be three unlock requests
28540 to release the resource in advance of session end.
28541 </para>
28543 <table id="functions-advisory-locks-table">
28544 <title>Advisory Lock Functions</title>
28545 <tgroup cols="1">
28546 <thead>
28547 <row>
28548 <entry role="func_table_entry"><para role="func_signature">
28549 Function
28550 </para>
28551 <para>
28552 Description
28553 </para></entry>
28554 </row>
28555 </thead>
28557 <tbody>
28558 <row>
28559 <entry role="func_table_entry"><para role="func_signature">
28560 <indexterm>
28561 <primary>pg_advisory_lock</primary>
28562 </indexterm>
28563 <function>pg_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28564 <returnvalue>void</returnvalue>
28565 </para>
28566 <para role="func_signature">
28567 <function>pg_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28568 <returnvalue>void</returnvalue>
28569 </para>
28570 <para>
28571 Obtains an exclusive session-level advisory lock, waiting if necessary.
28572 </para></entry>
28573 </row>
28575 <row>
28576 <entry role="func_table_entry"><para role="func_signature">
28577 <indexterm>
28578 <primary>pg_advisory_lock_shared</primary>
28579 </indexterm>
28580 <function>pg_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28581 <returnvalue>void</returnvalue>
28582 </para>
28583 <para role="func_signature">
28584 <function>pg_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28585 <returnvalue>void</returnvalue>
28586 </para>
28587 <para>
28588 Obtains a shared session-level advisory lock, waiting if necessary.
28589 </para></entry>
28590 </row>
28592 <row>
28593 <entry role="func_table_entry"><para role="func_signature">
28594 <indexterm>
28595 <primary>pg_advisory_unlock</primary>
28596 </indexterm>
28597 <function>pg_advisory_unlock</function> ( <parameter>key</parameter> <type>bigint</type> )
28598 <returnvalue>boolean</returnvalue>
28599 </para>
28600 <para role="func_signature">
28601 <function>pg_advisory_unlock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28602 <returnvalue>boolean</returnvalue>
28603 </para>
28604 <para>
28605 Releases a previously-acquired exclusive session-level advisory lock.
28606 Returns <literal>true</literal> if the lock is successfully released.
28607 If the lock was not held, <literal>false</literal> is returned, and in
28608 addition, an SQL warning will be reported by the server.
28609 </para></entry>
28610 </row>
28612 <row>
28613 <entry role="func_table_entry"><para role="func_signature">
28614 <indexterm>
28615 <primary>pg_advisory_unlock_all</primary>
28616 </indexterm>
28617 <function>pg_advisory_unlock_all</function> ()
28618 <returnvalue>void</returnvalue>
28619 </para>
28620 <para>
28621 Releases all session-level advisory locks held by the current session.
28622 (This function is implicitly invoked at session end, even if the
28623 client disconnects ungracefully.)
28624 </para></entry>
28625 </row>
28627 <row>
28628 <entry role="func_table_entry"><para role="func_signature">
28629 <indexterm>
28630 <primary>pg_advisory_unlock_shared</primary>
28631 </indexterm>
28632 <function>pg_advisory_unlock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28633 <returnvalue>boolean</returnvalue>
28634 </para>
28635 <para role="func_signature">
28636 <function>pg_advisory_unlock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28637 <returnvalue>boolean</returnvalue>
28638 </para>
28639 <para>
28640 Releases a previously-acquired shared session-level advisory lock.
28641 Returns <literal>true</literal> if the lock is successfully released.
28642 If the lock was not held, <literal>false</literal> is returned, and in
28643 addition, an SQL warning will be reported by the server.
28644 </para></entry>
28645 </row>
28647 <row>
28648 <entry role="func_table_entry"><para role="func_signature">
28649 <indexterm>
28650 <primary>pg_advisory_xact_lock</primary>
28651 </indexterm>
28652 <function>pg_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28653 <returnvalue>void</returnvalue>
28654 </para>
28655 <para role="func_signature">
28656 <function>pg_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28657 <returnvalue>void</returnvalue>
28658 </para>
28659 <para>
28660 Obtains an exclusive transaction-level advisory lock, waiting if
28661 necessary.
28662 </para></entry>
28663 </row>
28665 <row>
28666 <entry role="func_table_entry"><para role="func_signature">
28667 <indexterm>
28668 <primary>pg_advisory_xact_lock_shared</primary>
28669 </indexterm>
28670 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28671 <returnvalue>void</returnvalue>
28672 </para>
28673 <para role="func_signature">
28674 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28675 <returnvalue>void</returnvalue>
28676 </para>
28677 <para>
28678 Obtains a shared transaction-level advisory lock, waiting if
28679 necessary.
28680 </para></entry>
28681 </row>
28683 <row>
28684 <entry role="func_table_entry"><para role="func_signature">
28685 <indexterm>
28686 <primary>pg_try_advisory_lock</primary>
28687 </indexterm>
28688 <function>pg_try_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28689 <returnvalue>boolean</returnvalue>
28690 </para>
28691 <para role="func_signature">
28692 <function>pg_try_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28693 <returnvalue>boolean</returnvalue>
28694 </para>
28695 <para>
28696 Obtains an exclusive session-level advisory lock if available.
28697 This will either obtain the lock immediately and
28698 return <literal>true</literal>, or return <literal>false</literal>
28699 without waiting if the lock cannot be acquired immediately.
28700 </para></entry>
28701 </row>
28703 <row>
28704 <entry role="func_table_entry"><para role="func_signature">
28705 <indexterm>
28706 <primary>pg_try_advisory_lock_shared</primary>
28707 </indexterm>
28708 <function>pg_try_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28709 <returnvalue>boolean</returnvalue>
28710 </para>
28711 <para role="func_signature">
28712 <function>pg_try_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28713 <returnvalue>boolean</returnvalue>
28714 </para>
28715 <para>
28716 Obtains a shared session-level advisory lock if available.
28717 This will either obtain the lock immediately and
28718 return <literal>true</literal>, or return <literal>false</literal>
28719 without waiting if the lock cannot be acquired immediately.
28720 </para></entry>
28721 </row>
28723 <row>
28724 <entry role="func_table_entry"><para role="func_signature">
28725 <indexterm>
28726 <primary>pg_try_advisory_xact_lock</primary>
28727 </indexterm>
28728 <function>pg_try_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28729 <returnvalue>boolean</returnvalue>
28730 </para>
28731 <para role="func_signature">
28732 <function>pg_try_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28733 <returnvalue>boolean</returnvalue>
28734 </para>
28735 <para>
28736 Obtains an exclusive transaction-level advisory lock if available.
28737 This will either obtain the lock immediately and
28738 return <literal>true</literal>, or return <literal>false</literal>
28739 without waiting if the lock cannot be acquired immediately.
28740 </para></entry>
28741 </row>
28743 <row>
28744 <entry role="func_table_entry"><para role="func_signature">
28745 <indexterm>
28746 <primary>pg_try_advisory_xact_lock_shared</primary>
28747 </indexterm>
28748 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28749 <returnvalue>boolean</returnvalue>
28750 </para>
28751 <para role="func_signature">
28752 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28753 <returnvalue>boolean</returnvalue>
28754 </para>
28755 <para>
28756 Obtains a shared transaction-level advisory lock if available.
28757 This will either obtain the lock immediately and
28758 return <literal>true</literal>, or return <literal>false</literal>
28759 without waiting if the lock cannot be acquired immediately.
28760 </para></entry>
28761 </row>
28762 </tbody>
28763 </tgroup>
28764 </table>
28766 </sect2>
28768 </sect1>
28770 <sect1 id="functions-trigger">
28771 <title>Trigger Functions</title>
28773 <para>
28774 While many uses of triggers involve user-written trigger functions,
28775 <productname>PostgreSQL</productname> provides a few built-in trigger
28776 functions that can be used directly in user-defined triggers. These
28777 are summarized in <xref linkend="builtin-triggers-table"/>.
28778 (Additional built-in trigger functions exist, which implement foreign
28779 key constraints and deferred index constraints. Those are not documented
28780 here since users need not use them directly.)
28781 </para>
28783 <para>
28784 For more information about creating triggers, see
28785 <xref linkend="sql-createtrigger"/>.
28786 </para>
28788 <table id="builtin-triggers-table">
28789 <title>Built-In Trigger Functions</title>
28790 <tgroup cols="1">
28791 <thead>
28792 <row>
28793 <entry role="func_table_entry"><para role="func_signature">
28794 Function
28795 </para>
28796 <para>
28797 Description
28798 </para>
28799 <para>
28800 Example Usage
28801 </para></entry>
28802 </row>
28803 </thead>
28805 <tbody>
28806 <row>
28807 <entry role="func_table_entry"><para role="func_signature">
28808 <indexterm>
28809 <primary>suppress_redundant_updates_trigger</primary>
28810 </indexterm>
28811 <function>suppress_redundant_updates_trigger</function> ( )
28812 <returnvalue>trigger</returnvalue>
28813 </para>
28814 <para>
28815 Suppresses do-nothing update operations. See below for details.
28816 </para>
28817 <para>
28818 <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()</literal>
28819 </para></entry>
28820 </row>
28822 <row>
28823 <entry role="func_table_entry"><para role="func_signature">
28824 <indexterm>
28825 <primary>tsvector_update_trigger</primary>
28826 </indexterm>
28827 <function>tsvector_update_trigger</function> ( )
28828 <returnvalue>trigger</returnvalue>
28829 </para>
28830 <para>
28831 Automatically updates a <type>tsvector</type> column from associated
28832 plain-text document column(s). The text search configuration to use
28833 is specified by name as a trigger argument. See
28834 <xref linkend="textsearch-update-triggers"/> for details.
28835 </para>
28836 <para>
28837 <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal>
28838 </para></entry>
28839 </row>
28841 <row>
28842 <entry role="func_table_entry"><para role="func_signature">
28843 <indexterm>
28844 <primary>tsvector_update_trigger_column</primary>
28845 </indexterm>
28846 <function>tsvector_update_trigger_column</function> ( )
28847 <returnvalue>trigger</returnvalue>
28848 </para>
28849 <para>
28850 Automatically updates a <type>tsvector</type> column from associated
28851 plain-text document column(s). The text search configuration to use
28852 is taken from a <type>regconfig</type> column of the table. See
28853 <xref linkend="textsearch-update-triggers"/> for details.
28854 </para>
28855 <para>
28856 <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)</literal>
28857 </para></entry>
28858 </row>
28859 </tbody>
28860 </tgroup>
28861 </table>
28863 <para>
28864 The <function>suppress_redundant_updates_trigger</function> function,
28865 when applied as a row-level <literal>BEFORE UPDATE</literal> trigger,
28866 will prevent any update that does not actually change the data in the
28867 row from taking place. This overrides the normal behavior which always
28868 performs a physical row update
28869 regardless of whether or not the data has changed. (This normal behavior
28870 makes updates run faster, since no checking is required, and is also
28871 useful in certain cases.)
28872 </para>
28874 <para>
28875 Ideally, you should avoid running updates that don't actually
28876 change the data in the record. Redundant updates can cost considerable
28877 unnecessary time, especially if there are lots of indexes to alter,
28878 and space in dead rows that will eventually have to be vacuumed.
28879 However, detecting such situations in client code is not
28880 always easy, or even possible, and writing expressions to detect
28881 them can be error-prone. An alternative is to use
28882 <function>suppress_redundant_updates_trigger</function>, which will skip
28883 updates that don't change the data. You should use this with care,
28884 however. The trigger takes a small but non-trivial time for each record,
28885 so if most of the records affected by updates do actually change,
28886 use of this trigger will make updates run slower on average.
28887 </para>
28889 <para>
28890 The <function>suppress_redundant_updates_trigger</function> function can be
28891 added to a table like this:
28892 <programlisting>
28893 CREATE TRIGGER z_min_update
28894 BEFORE UPDATE ON tablename
28895 FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger();
28896 </programlisting>
28897 In most cases, you need to fire this trigger last for each row, so that
28898 it does not override other triggers that might wish to alter the row.
28899 Bearing in mind that triggers fire in name order, you would therefore
28900 choose a trigger name that comes after the name of any other trigger
28901 you might have on the table. (Hence the <quote>z</quote> prefix in the
28902 example.)
28903 </para>
28904 </sect1>
28906 <sect1 id="functions-event-triggers">
28907 <title>Event Trigger Functions</title>
28909 <para>
28910 <productname>PostgreSQL</productname> provides these helper functions
28911 to retrieve information from event triggers.
28912 </para>
28914 <para>
28915 For more information about event triggers,
28916 see <xref linkend="event-triggers"/>.
28917 </para>
28919 <sect2 id="pg-event-trigger-ddl-command-end-functions">
28920 <title>Capturing Changes at Command End</title>
28922 <indexterm>
28923 <primary>pg_event_trigger_ddl_commands</primary>
28924 </indexterm>
28926 <synopsis>
28927 <function>pg_event_trigger_ddl_commands</function> () <returnvalue>setof record</returnvalue>
28928 </synopsis>
28930 <para>
28931 <function>pg_event_trigger_ddl_commands</function> returns a list of
28932 <acronym>DDL</acronym> commands executed by each user action,
28933 when invoked in a function attached to a
28934 <literal>ddl_command_end</literal> event trigger. If called in any other
28935 context, an error is raised.
28936 <function>pg_event_trigger_ddl_commands</function> returns one row for each
28937 base command executed; some commands that are a single SQL sentence
28938 may return more than one row. This function returns the following
28939 columns:
28941 <informaltable>
28942 <tgroup cols="3">
28943 <thead>
28944 <row>
28945 <entry>Name</entry>
28946 <entry>Type</entry>
28947 <entry>Description</entry>
28948 </row>
28949 </thead>
28951 <tbody>
28952 <row>
28953 <entry><literal>classid</literal></entry>
28954 <entry><type>oid</type></entry>
28955 <entry>OID of catalog the object belongs in</entry>
28956 </row>
28957 <row>
28958 <entry><literal>objid</literal></entry>
28959 <entry><type>oid</type></entry>
28960 <entry>OID of the object itself</entry>
28961 </row>
28962 <row>
28963 <entry><literal>objsubid</literal></entry>
28964 <entry><type>integer</type></entry>
28965 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
28966 </row>
28967 <row>
28968 <entry><literal>command_tag</literal></entry>
28969 <entry><type>text</type></entry>
28970 <entry>Command tag</entry>
28971 </row>
28972 <row>
28973 <entry><literal>object_type</literal></entry>
28974 <entry><type>text</type></entry>
28975 <entry>Type of the object</entry>
28976 </row>
28977 <row>
28978 <entry><literal>schema_name</literal></entry>
28979 <entry><type>text</type></entry>
28980 <entry>
28981 Name of the schema the object belongs in, if any; otherwise <literal>NULL</literal>.
28982 No quoting is applied.
28983 </entry>
28984 </row>
28985 <row>
28986 <entry><literal>object_identity</literal></entry>
28987 <entry><type>text</type></entry>
28988 <entry>
28989 Text rendering of the object identity, schema-qualified. Each
28990 identifier included in the identity is quoted if necessary.
28991 </entry>
28992 </row>
28993 <row>
28994 <entry><literal>in_extension</literal></entry>
28995 <entry><type>boolean</type></entry>
28996 <entry>True if the command is part of an extension script</entry>
28997 </row>
28998 <row>
28999 <entry><literal>command</literal></entry>
29000 <entry><type>pg_ddl_command</type></entry>
29001 <entry>
29002 A complete representation of the command, in internal format.
29003 This cannot be output directly, but it can be passed to other
29004 functions to obtain different pieces of information about the
29005 command.
29006 </entry>
29007 </row>
29008 </tbody>
29009 </tgroup>
29010 </informaltable>
29011 </para>
29012 </sect2>
29014 <sect2 id="pg-event-trigger-sql-drop-functions">
29015 <title>Processing Objects Dropped by a DDL Command</title>
29017 <indexterm>
29018 <primary>pg_event_trigger_dropped_objects</primary>
29019 </indexterm>
29021 <synopsis>
29022 <function>pg_event_trigger_dropped_objects</function> () <returnvalue>setof record</returnvalue>
29023 </synopsis>
29025 <para>
29026 <function>pg_event_trigger_dropped_objects</function> returns a list of all objects
29027 dropped by the command in whose <literal>sql_drop</literal> event it is called.
29028 If called in any other context, an error is raised.
29029 This function returns the following columns:
29031 <informaltable>
29032 <tgroup cols="3">
29033 <thead>
29034 <row>
29035 <entry>Name</entry>
29036 <entry>Type</entry>
29037 <entry>Description</entry>
29038 </row>
29039 </thead>
29041 <tbody>
29042 <row>
29043 <entry><literal>classid</literal></entry>
29044 <entry><type>oid</type></entry>
29045 <entry>OID of catalog the object belonged in</entry>
29046 </row>
29047 <row>
29048 <entry><literal>objid</literal></entry>
29049 <entry><type>oid</type></entry>
29050 <entry>OID of the object itself</entry>
29051 </row>
29052 <row>
29053 <entry><literal>objsubid</literal></entry>
29054 <entry><type>integer</type></entry>
29055 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
29056 </row>
29057 <row>
29058 <entry><literal>original</literal></entry>
29059 <entry><type>boolean</type></entry>
29060 <entry>True if this was one of the root object(s) of the deletion</entry>
29061 </row>
29062 <row>
29063 <entry><literal>normal</literal></entry>
29064 <entry><type>boolean</type></entry>
29065 <entry>
29066 True if there was a normal dependency relationship
29067 in the dependency graph leading to this object
29068 </entry>
29069 </row>
29070 <row>
29071 <entry><literal>is_temporary</literal></entry>
29072 <entry><type>boolean</type></entry>
29073 <entry>
29074 True if this was a temporary object
29075 </entry>
29076 </row>
29077 <row>
29078 <entry><literal>object_type</literal></entry>
29079 <entry><type>text</type></entry>
29080 <entry>Type of the object</entry>
29081 </row>
29082 <row>
29083 <entry><literal>schema_name</literal></entry>
29084 <entry><type>text</type></entry>
29085 <entry>
29086 Name of the schema the object belonged in, if any; otherwise <literal>NULL</literal>.
29087 No quoting is applied.
29088 </entry>
29089 </row>
29090 <row>
29091 <entry><literal>object_name</literal></entry>
29092 <entry><type>text</type></entry>
29093 <entry>
29094 Name of the object, if the combination of schema and name can be
29095 used as a unique identifier for the object; otherwise <literal>NULL</literal>.
29096 No quoting is applied, and name is never schema-qualified.
29097 </entry>
29098 </row>
29099 <row>
29100 <entry><literal>object_identity</literal></entry>
29101 <entry><type>text</type></entry>
29102 <entry>
29103 Text rendering of the object identity, schema-qualified. Each
29104 identifier included in the identity is quoted if necessary.
29105 </entry>
29106 </row>
29107 <row>
29108 <entry><literal>address_names</literal></entry>
29109 <entry><type>text[]</type></entry>
29110 <entry>
29111 An array that, together with <literal>object_type</literal> and
29112 <literal>address_args</literal>, can be used by
29113 the <function>pg_get_object_address</function> function to
29114 recreate the object address in a remote server containing an
29115 identically named object of the same kind.
29116 </entry>
29117 </row>
29118 <row>
29119 <entry><literal>address_args</literal></entry>
29120 <entry><type>text[]</type></entry>
29121 <entry>
29122 Complement for <literal>address_names</literal>
29123 </entry>
29124 </row>
29125 </tbody>
29126 </tgroup>
29127 </informaltable>
29128 </para>
29130 <para>
29131 The <function>pg_event_trigger_dropped_objects</function> function can be used
29132 in an event trigger like this:
29133 <programlisting>
29134 CREATE FUNCTION test_event_trigger_for_drops()
29135 RETURNS event_trigger LANGUAGE plpgsql AS $$
29136 DECLARE
29137 obj record;
29138 BEGIN
29139 FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
29140 LOOP
29141 RAISE NOTICE '% dropped object: % %.% %',
29142 tg_tag,
29143 obj.object_type,
29144 obj.schema_name,
29145 obj.object_name,
29146 obj.object_identity;
29147 END LOOP;
29148 END;
29150 CREATE EVENT TRIGGER test_event_trigger_for_drops
29151 ON sql_drop
29152 EXECUTE FUNCTION test_event_trigger_for_drops();
29153 </programlisting>
29154 </para>
29155 </sect2>
29157 <sect2 id="pg-event-trigger-table-rewrite-functions">
29158 <title>Handling a Table Rewrite Event</title>
29160 <para>
29161 The functions shown in
29162 <xref linkend="functions-event-trigger-table-rewrite"/>
29163 provide information about a table for which a
29164 <literal>table_rewrite</literal> event has just been called.
29165 If called in any other context, an error is raised.
29166 </para>
29168 <table id="functions-event-trigger-table-rewrite">
29169 <title>Table Rewrite Information Functions</title>
29170 <tgroup cols="1">
29171 <thead>
29172 <row>
29173 <entry role="func_table_entry"><para role="func_signature">
29174 Function
29175 </para>
29176 <para>
29177 Description
29178 </para></entry>
29179 </row>
29180 </thead>
29182 <tbody>
29183 <row>
29184 <entry role="func_table_entry"><para role="func_signature">
29185 <indexterm>
29186 <primary>pg_event_trigger_table_rewrite_oid</primary>
29187 </indexterm>
29188 <function>pg_event_trigger_table_rewrite_oid</function> ()
29189 <returnvalue>oid</returnvalue>
29190 </para>
29191 <para>
29192 Returns the OID of the table about to be rewritten.
29193 </para></entry>
29194 </row>
29196 <row>
29197 <entry role="func_table_entry"><para role="func_signature">
29198 <indexterm>
29199 <primary>pg_event_trigger_table_rewrite_reason</primary>
29200 </indexterm>
29201 <function>pg_event_trigger_table_rewrite_reason</function> ()
29202 <returnvalue>integer</returnvalue>
29203 </para>
29204 <para>
29205 Returns a code explaining the reason(s) for rewriting. The exact
29206 meaning of the codes is release dependent.
29207 </para></entry>
29208 </row>
29209 </tbody>
29210 </tgroup>
29211 </table>
29213 <para>
29214 These functions can be used in an event trigger like this:
29215 <programlisting>
29216 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
29217 RETURNS event_trigger
29218 LANGUAGE plpgsql AS
29220 BEGIN
29221 RAISE NOTICE 'rewriting table % for reason %',
29222 pg_event_trigger_table_rewrite_oid()::regclass,
29223 pg_event_trigger_table_rewrite_reason();
29224 END;
29227 CREATE EVENT TRIGGER test_table_rewrite_oid
29228 ON table_rewrite
29229 EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
29230 </programlisting>
29231 </para>
29232 </sect2>
29233 </sect1>
29235 <sect1 id="functions-statistics">
29236 <title>Statistics Information Functions</title>
29238 <indexterm zone="functions-statistics">
29239 <primary>function</primary>
29240 <secondary>statistics</secondary>
29241 </indexterm>
29243 <para>
29244 <productname>PostgreSQL</productname> provides a function to inspect complex
29245 statistics defined using the <command>CREATE STATISTICS</command> command.
29246 </para>
29248 <sect2 id="functions-statistics-mcv">
29249 <title>Inspecting MCV Lists</title>
29251 <indexterm>
29252 <primary>pg_mcv_list_items</primary>
29253 </indexterm>
29255 <synopsis>
29256 <function>pg_mcv_list_items</function> ( <type>pg_mcv_list</type> ) <returnvalue>setof record</returnvalue>
29257 </synopsis>
29259 <para>
29260 <function>pg_mcv_list_items</function> returns a set of records describing
29261 all items stored in a multi-column <acronym>MCV</acronym> list. It
29262 returns the following columns:
29264 <informaltable>
29265 <tgroup cols="3">
29266 <thead>
29267 <row>
29268 <entry>Name</entry>
29269 <entry>Type</entry>
29270 <entry>Description</entry>
29271 </row>
29272 </thead>
29274 <tbody>
29275 <row>
29276 <entry><literal>index</literal></entry>
29277 <entry><type>integer</type></entry>
29278 <entry>index of the item in the <acronym>MCV</acronym> list</entry>
29279 </row>
29280 <row>
29281 <entry><literal>values</literal></entry>
29282 <entry><type>text[]</type></entry>
29283 <entry>values stored in the MCV item</entry>
29284 </row>
29285 <row>
29286 <entry><literal>nulls</literal></entry>
29287 <entry><type>boolean[]</type></entry>
29288 <entry>flags identifying <literal>NULL</literal> values</entry>
29289 </row>
29290 <row>
29291 <entry><literal>frequency</literal></entry>
29292 <entry><type>double precision</type></entry>
29293 <entry>frequency of this <acronym>MCV</acronym> item</entry>
29294 </row>
29295 <row>
29296 <entry><literal>base_frequency</literal></entry>
29297 <entry><type>double precision</type></entry>
29298 <entry>base frequency of this <acronym>MCV</acronym> item</entry>
29299 </row>
29300 </tbody>
29301 </tgroup>
29302 </informaltable>
29303 </para>
29305 <para>
29306 The <function>pg_mcv_list_items</function> function can be used like this:
29308 <programlisting>
29309 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
29310 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
29311 </programlisting>
29313 Values of the <type>pg_mcv_list</type> type can be obtained only from the
29314 <structname>pg_statistic_ext_data</structname>.<structfield>stxdmcv</structfield>
29315 column.
29316 </para>
29317 </sect2>
29319 </sect1>
29321 </chapter>