doc: add ISO 8601 extended format example using to_char()
[pgsql.git] / doc / src / sgml / func.sgml
blobcec21e42c05b139d36e220f1ed2bb883c7c99cb8
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. For example:
723 <programlisting>
724 SELECT ROW(1,2.5,'this is a test') = ROW(1, 3, 'not the same');
726 SELECT ROW(table.*) IS NULL FROM table; -- detect all-null rows
728 SELECT ROW(table.*) IS NOT NULL FROM table; -- detect all-non-null rows
730 SELECT NOT(ROW(table.*) IS NOT NULL) FROM TABLE; -- detect at least one null in rows
731 </programlisting>
733 In some cases, it may be preferable to
734 write <replaceable>row</replaceable> <literal>IS DISTINCT FROM NULL</literal>
735 or <replaceable>row</replaceable> <literal>IS NOT DISTINCT FROM NULL</literal>,
736 which will simply check whether the overall row value is null without any
737 additional tests on the row fields.
738 </para>
740 <para>
741 <indexterm>
742 <primary>IS TRUE</primary>
743 </indexterm>
744 <indexterm>
745 <primary>IS NOT TRUE</primary>
746 </indexterm>
747 <indexterm>
748 <primary>IS FALSE</primary>
749 </indexterm>
750 <indexterm>
751 <primary>IS NOT FALSE</primary>
752 </indexterm>
753 <indexterm>
754 <primary>IS UNKNOWN</primary>
755 </indexterm>
756 <indexterm>
757 <primary>IS NOT UNKNOWN</primary>
758 </indexterm>
759 Boolean values can also be tested using the predicates
760 <synopsis>
761 <replaceable>boolean_expression</replaceable> IS TRUE
762 <replaceable>boolean_expression</replaceable> IS NOT TRUE
763 <replaceable>boolean_expression</replaceable> IS FALSE
764 <replaceable>boolean_expression</replaceable> IS NOT FALSE
765 <replaceable>boolean_expression</replaceable> IS UNKNOWN
766 <replaceable>boolean_expression</replaceable> IS NOT UNKNOWN
767 </synopsis>
768 These will always return true or false, never a null value, even when the
769 operand is null.
770 A null input is treated as the logical value <quote>unknown</quote>.
771 Notice that <literal>IS UNKNOWN</literal> and <literal>IS NOT UNKNOWN</literal> are
772 effectively the same as <literal>IS NULL</literal> and
773 <literal>IS NOT NULL</literal>, respectively, except that the input
774 expression must be of Boolean type.
775 </para>
777 <para>
778 Some comparison-related functions are also available, as shown in <xref
779 linkend="functions-comparison-func-table"/>.
780 </para>
782 <table id="functions-comparison-func-table">
783 <title>Comparison Functions</title>
784 <tgroup cols="1">
785 <thead>
786 <row>
787 <entry role="func_table_entry"><para role="func_signature">
788 Function
789 </para>
790 <para>
791 Description
792 </para>
793 <para>
794 Example(s)
795 </para></entry>
796 </row>
797 </thead>
799 <tbody>
800 <row>
801 <entry role="func_table_entry"><para role="func_signature">
802 <indexterm>
803 <primary>num_nonnulls</primary>
804 </indexterm>
805 <function>num_nonnulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
806 <returnvalue>integer</returnvalue>
807 </para>
808 <para>
809 Returns the number of non-null arguments.
810 </para>
811 <para>
812 <literal>num_nonnulls(1, NULL, 2)</literal>
813 <returnvalue>2</returnvalue>
814 </para></entry>
815 </row>
816 <row>
817 <entry role="func_table_entry"><para role="func_signature">
818 <indexterm>
819 <primary>num_nulls</primary>
820 </indexterm>
821 <function>num_nulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
822 <returnvalue>integer</returnvalue>
823 </para>
824 <para>
825 Returns the number of null arguments.
826 </para>
827 <para>
828 <literal>num_nulls(1, NULL, 2)</literal>
829 <returnvalue>1</returnvalue>
830 </para></entry>
831 </row>
832 </tbody>
833 </tgroup>
834 </table>
836 </sect1>
838 <sect1 id="functions-math">
839 <title>Mathematical Functions and Operators</title>
841 <para>
842 Mathematical operators are provided for many
843 <productname>PostgreSQL</productname> types. For types without
844 standard mathematical conventions
845 (e.g., date/time types) we
846 describe the actual behavior in subsequent sections.
847 </para>
849 <para>
850 <xref linkend="functions-math-op-table"/> shows the mathematical
851 operators that are available for the standard numeric types.
852 Unless otherwise noted, operators shown as
853 accepting <replaceable>numeric_type</replaceable> are available for all
854 the types <type>smallint</type>, <type>integer</type>,
855 <type>bigint</type>, <type>numeric</type>, <type>real</type>,
856 and <type>double precision</type>.
857 Operators shown as accepting <replaceable>integral_type</replaceable>
858 are available for the types <type>smallint</type>, <type>integer</type>,
859 and <type>bigint</type>.
860 Except where noted, each form of an operator returns the same data type
861 as its argument(s). Calls involving multiple argument data types, such
862 as <type>integer</type> <literal>+</literal> <type>numeric</type>,
863 are resolved by using the type appearing later in these lists.
864 </para>
866 <table id="functions-math-op-table">
867 <title>Mathematical Operators</title>
869 <tgroup cols="1">
870 <thead>
871 <row>
872 <entry role="func_table_entry"><para role="func_signature">
873 Operator
874 </para>
875 <para>
876 Description
877 </para>
878 <para>
879 Example(s)
880 </para></entry>
881 </row>
882 </thead>
884 <tbody>
885 <row>
886 <entry role="func_table_entry"><para role="func_signature">
887 <replaceable>numeric_type</replaceable> <literal>+</literal> <replaceable>numeric_type</replaceable>
888 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
889 </para>
890 <para>
891 Addition
892 </para>
893 <para>
894 <literal>2 + 3</literal>
895 <returnvalue>5</returnvalue>
896 </para></entry>
897 </row>
899 <row>
900 <entry role="func_table_entry"><para role="func_signature">
901 <literal>+</literal> <replaceable>numeric_type</replaceable>
902 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
903 </para>
904 <para>
905 Unary plus (no operation)
906 </para>
907 <para>
908 <literal>+ 3.5</literal>
909 <returnvalue>3.5</returnvalue>
910 </para></entry>
911 </row>
913 <row>
914 <entry role="func_table_entry"><para role="func_signature">
915 <replaceable>numeric_type</replaceable> <literal>-</literal> <replaceable>numeric_type</replaceable>
916 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
917 </para>
918 <para>
919 Subtraction
920 </para>
921 <para>
922 <literal>2 - 3</literal>
923 <returnvalue>-1</returnvalue>
924 </para></entry>
925 </row>
927 <row>
928 <entry role="func_table_entry"><para role="func_signature">
929 <literal>-</literal> <replaceable>numeric_type</replaceable>
930 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
931 </para>
932 <para>
933 Negation
934 </para>
935 <para>
936 <literal>- (-4)</literal>
937 <returnvalue>4</returnvalue>
938 </para></entry>
939 </row>
941 <row>
942 <entry role="func_table_entry"><para role="func_signature">
943 <replaceable>numeric_type</replaceable> <literal>*</literal> <replaceable>numeric_type</replaceable>
944 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
945 </para>
946 <para>
947 Multiplication
948 </para>
949 <para>
950 <literal>2 * 3</literal>
951 <returnvalue>6</returnvalue>
952 </para></entry>
953 </row>
955 <row>
956 <entry role="func_table_entry"><para role="func_signature">
957 <replaceable>numeric_type</replaceable> <literal>/</literal> <replaceable>numeric_type</replaceable>
958 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
959 </para>
960 <para>
961 Division (for integral types, division truncates the result towards
962 zero)
963 </para>
964 <para>
965 <literal>5.0 / 2</literal>
966 <returnvalue>2.5000000000000000</returnvalue>
967 </para>
968 <para>
969 <literal>5 / 2</literal>
970 <returnvalue>2</returnvalue>
971 </para>
972 <para>
973 <literal>(-5) / 2</literal>
974 <returnvalue>-2</returnvalue>
975 </para></entry>
976 </row>
978 <row>
979 <entry role="func_table_entry"><para role="func_signature">
980 <replaceable>numeric_type</replaceable> <literal>%</literal> <replaceable>numeric_type</replaceable>
981 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
982 </para>
983 <para>
984 Modulo (remainder); available for <type>smallint</type>,
985 <type>integer</type>, <type>bigint</type>, and <type>numeric</type>
986 </para>
987 <para>
988 <literal>5 % 4</literal>
989 <returnvalue>1</returnvalue>
990 </para></entry>
991 </row>
993 <row>
994 <entry role="func_table_entry"><para role="func_signature">
995 <type>numeric</type> <literal>^</literal> <type>numeric</type>
996 <returnvalue>numeric</returnvalue>
997 </para>
998 <para role="func_signature">
999 <type>double precision</type> <literal>^</literal> <type>double precision</type>
1000 <returnvalue>double precision</returnvalue>
1001 </para>
1002 <para>
1003 Exponentiation
1004 </para>
1005 <para>
1006 <literal>2 ^ 3</literal>
1007 <returnvalue>8</returnvalue>
1008 </para>
1009 <para>
1010 Unlike typical mathematical practice, multiple uses of
1011 <literal>^</literal> will associate left to right by default:
1012 </para>
1013 <para>
1014 <literal>2 ^ 3 ^ 3</literal>
1015 <returnvalue>512</returnvalue>
1016 </para>
1017 <para>
1018 <literal>2 ^ (3 ^ 3)</literal>
1019 <returnvalue>134217728</returnvalue>
1020 </para></entry>
1021 </row>
1023 <row>
1024 <entry role="func_table_entry"><para role="func_signature">
1025 <literal>|/</literal> <type>double precision</type>
1026 <returnvalue>double precision</returnvalue>
1027 </para>
1028 <para>
1029 Square root
1030 </para>
1031 <para>
1032 <literal>|/ 25.0</literal>
1033 <returnvalue>5</returnvalue>
1034 </para></entry>
1035 </row>
1037 <row>
1038 <entry role="func_table_entry"><para role="func_signature">
1039 <literal>||/</literal> <type>double precision</type>
1040 <returnvalue>double precision</returnvalue>
1041 </para>
1042 <para>
1043 Cube root
1044 </para>
1045 <para>
1046 <literal>||/ 64.0</literal>
1047 <returnvalue>4</returnvalue>
1048 </para></entry>
1049 </row>
1051 <row>
1052 <entry role="func_table_entry"><para role="func_signature">
1053 <literal>@</literal> <replaceable>numeric_type</replaceable>
1054 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1055 </para>
1056 <para>
1057 Absolute value
1058 </para>
1059 <para>
1060 <literal>@ -5.0</literal>
1061 <returnvalue>5.0</returnvalue>
1062 </para></entry>
1063 </row>
1065 <row>
1066 <entry role="func_table_entry"><para role="func_signature">
1067 <replaceable>integral_type</replaceable> <literal>&amp;</literal> <replaceable>integral_type</replaceable>
1068 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1069 </para>
1070 <para>
1071 Bitwise AND
1072 </para>
1073 <para>
1074 <literal>91 &amp; 15</literal>
1075 <returnvalue>11</returnvalue>
1076 </para></entry>
1077 </row>
1079 <row>
1080 <entry role="func_table_entry"><para role="func_signature">
1081 <replaceable>integral_type</replaceable> <literal>|</literal> <replaceable>integral_type</replaceable>
1082 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1083 </para>
1084 <para>
1085 Bitwise OR
1086 </para>
1087 <para>
1088 <literal>32 | 3</literal>
1089 <returnvalue>35</returnvalue>
1090 </para></entry>
1091 </row>
1093 <row>
1094 <entry role="func_table_entry"><para role="func_signature">
1095 <replaceable>integral_type</replaceable> <literal>#</literal> <replaceable>integral_type</replaceable>
1096 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1097 </para>
1098 <para>
1099 Bitwise exclusive OR
1100 </para>
1101 <para>
1102 <literal>17 # 5</literal>
1103 <returnvalue>20</returnvalue>
1104 </para></entry>
1105 </row>
1107 <row>
1108 <entry role="func_table_entry"><para role="func_signature">
1109 <literal>~</literal> <replaceable>integral_type</replaceable>
1110 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1111 </para>
1112 <para>
1113 Bitwise NOT
1114 </para>
1115 <para>
1116 <literal>~1</literal>
1117 <returnvalue>-2</returnvalue>
1118 </para></entry>
1119 </row>
1121 <row>
1122 <entry role="func_table_entry"><para role="func_signature">
1123 <replaceable>integral_type</replaceable> <literal>&lt;&lt;</literal> <type>integer</type>
1124 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1125 </para>
1126 <para>
1127 Bitwise shift left
1128 </para>
1129 <para>
1130 <literal>1 &lt;&lt; 4</literal>
1131 <returnvalue>16</returnvalue>
1132 </para></entry>
1133 </row>
1135 <row>
1136 <entry role="func_table_entry"><para role="func_signature">
1137 <replaceable>integral_type</replaceable> <literal>&gt;&gt;</literal> <type>integer</type>
1138 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1139 </para>
1140 <para>
1141 Bitwise shift right
1142 </para>
1143 <para>
1144 <literal>8 &gt;&gt; 2</literal>
1145 <returnvalue>2</returnvalue>
1146 </para></entry>
1147 </row>
1149 </tbody>
1150 </tgroup>
1151 </table>
1153 <para>
1154 <xref linkend="functions-math-func-table"/> shows the available
1155 mathematical functions.
1156 Many of these functions are provided in multiple forms with different
1157 argument types.
1158 Except where noted, any given form of a function returns the same
1159 data type as its argument(s); cross-type cases are resolved in the
1160 same way as explained above for operators.
1161 The functions working with <type>double precision</type> data are mostly
1162 implemented on top of the host system's C library; accuracy and behavior in
1163 boundary cases can therefore vary depending on the host system.
1164 </para>
1166 <table id="functions-math-func-table">
1167 <title>Mathematical Functions</title>
1168 <tgroup cols="1">
1169 <thead>
1170 <row>
1171 <entry role="func_table_entry"><para role="func_signature">
1172 Function
1173 </para>
1174 <para>
1175 Description
1176 </para>
1177 <para>
1178 Example(s)
1179 </para></entry>
1180 </row>
1181 </thead>
1183 <tbody>
1184 <row>
1185 <entry role="func_table_entry"><para role="func_signature">
1186 <indexterm>
1187 <primary>abs</primary>
1188 </indexterm>
1189 <function>abs</function> ( <replaceable>numeric_type</replaceable> )
1190 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1191 </para>
1192 <para>
1193 Absolute value
1194 </para>
1195 <para>
1196 <literal>abs(-17.4)</literal>
1197 <returnvalue>17.4</returnvalue>
1198 </para></entry>
1199 </row>
1201 <row>
1202 <entry role="func_table_entry"><para role="func_signature">
1203 <indexterm>
1204 <primary>cbrt</primary>
1205 </indexterm>
1206 <function>cbrt</function> ( <type>double precision</type> )
1207 <returnvalue>double precision</returnvalue>
1208 </para>
1209 <para>
1210 Cube root
1211 </para>
1212 <para>
1213 <literal>cbrt(64.0)</literal>
1214 <returnvalue>4</returnvalue>
1215 </para></entry>
1216 </row>
1218 <row>
1219 <entry role="func_table_entry"><para role="func_signature">
1220 <indexterm>
1221 <primary>ceil</primary>
1222 </indexterm>
1223 <function>ceil</function> ( <type>numeric</type> )
1224 <returnvalue>numeric</returnvalue>
1225 </para>
1226 <para role="func_signature">
1227 <function>ceil</function> ( <type>double precision</type> )
1228 <returnvalue>double precision</returnvalue>
1229 </para>
1230 <para>
1231 Nearest integer greater than or equal to argument
1232 </para>
1233 <para>
1234 <literal>ceil(42.2)</literal>
1235 <returnvalue>43</returnvalue>
1236 </para>
1237 <para>
1238 <literal>ceil(-42.8)</literal>
1239 <returnvalue>-42</returnvalue>
1240 </para></entry>
1241 </row>
1243 <row>
1244 <entry role="func_table_entry"><para role="func_signature">
1245 <indexterm>
1246 <primary>ceiling</primary>
1247 </indexterm>
1248 <function>ceiling</function> ( <type>numeric</type> )
1249 <returnvalue>numeric</returnvalue>
1250 </para>
1251 <para role="func_signature">
1252 <function>ceiling</function> ( <type>double precision</type> )
1253 <returnvalue>double precision</returnvalue>
1254 </para>
1255 <para>
1256 Nearest integer greater than or equal to argument (same
1257 as <function>ceil</function>)
1258 </para>
1259 <para>
1260 <literal>ceiling(95.3)</literal>
1261 <returnvalue>96</returnvalue>
1262 </para></entry>
1263 </row>
1265 <row>
1266 <entry role="func_table_entry"><para role="func_signature">
1267 <indexterm>
1268 <primary>degrees</primary>
1269 </indexterm>
1270 <function>degrees</function> ( <type>double precision</type> )
1271 <returnvalue>double precision</returnvalue>
1272 </para>
1273 <para>
1274 Converts radians to degrees
1275 </para>
1276 <para>
1277 <literal>degrees(0.5)</literal>
1278 <returnvalue>28.64788975654116</returnvalue>
1279 </para></entry>
1280 </row>
1282 <row>
1283 <entry role="func_table_entry"><para role="func_signature">
1284 <indexterm>
1285 <primary>div</primary>
1286 </indexterm>
1287 <function>div</function> ( <parameter>y</parameter> <type>numeric</type>,
1288 <parameter>x</parameter> <type>numeric</type> )
1289 <returnvalue>numeric</returnvalue>
1290 </para>
1291 <para>
1292 Integer quotient of <parameter>y</parameter>/<parameter>x</parameter>
1293 (truncates towards zero)
1294 </para>
1295 <para>
1296 <literal>div(9, 4)</literal>
1297 <returnvalue>2</returnvalue>
1298 </para></entry>
1299 </row>
1301 <row>
1302 <entry role="func_table_entry"><para role="func_signature">
1303 <indexterm>
1304 <primary>erf</primary>
1305 </indexterm>
1306 <function>erf</function> ( <type>double precision</type> )
1307 <returnvalue>double precision</returnvalue>
1308 </para>
1309 <para>
1310 Error function
1311 </para>
1312 <para>
1313 <literal>erf(1.0)</literal>
1314 <returnvalue>0.8427007929497149</returnvalue>
1315 </para></entry>
1316 </row>
1318 <row>
1319 <entry role="func_table_entry"><para role="func_signature">
1320 <indexterm>
1321 <primary>erfc</primary>
1322 </indexterm>
1323 <function>erfc</function> ( <type>double precision</type> )
1324 <returnvalue>double precision</returnvalue>
1325 </para>
1326 <para>
1327 Complementary error function (<literal>1 - erf(x)</literal>, without
1328 loss of precision for large inputs)
1329 </para>
1330 <para>
1331 <literal>erfc(1.0)</literal>
1332 <returnvalue>0.15729920705028513</returnvalue>
1333 </para></entry>
1334 </row>
1336 <row>
1337 <entry role="func_table_entry"><para role="func_signature">
1338 <indexterm>
1339 <primary>exp</primary>
1340 </indexterm>
1341 <function>exp</function> ( <type>numeric</type> )
1342 <returnvalue>numeric</returnvalue>
1343 </para>
1344 <para role="func_signature">
1345 <function>exp</function> ( <type>double precision</type> )
1346 <returnvalue>double precision</returnvalue>
1347 </para>
1348 <para>
1349 Exponential (<literal>e</literal> raised to the given power)
1350 </para>
1351 <para>
1352 <literal>exp(1.0)</literal>
1353 <returnvalue>2.7182818284590452</returnvalue>
1354 </para></entry>
1355 </row>
1357 <row>
1358 <entry role="func_table_entry"><para role="func_signature">
1359 <indexterm id="function-factorial">
1360 <primary>factorial</primary>
1361 </indexterm>
1362 <function>factorial</function> ( <type>bigint</type> )
1363 <returnvalue>numeric</returnvalue>
1364 </para>
1365 <para>
1366 Factorial
1367 </para>
1368 <para>
1369 <literal>factorial(5)</literal>
1370 <returnvalue>120</returnvalue>
1371 </para></entry>
1372 </row>
1374 <row>
1375 <entry role="func_table_entry"><para role="func_signature">
1376 <indexterm>
1377 <primary>floor</primary>
1378 </indexterm>
1379 <function>floor</function> ( <type>numeric</type> )
1380 <returnvalue>numeric</returnvalue>
1381 </para>
1382 <para role="func_signature">
1383 <function>floor</function> ( <type>double precision</type> )
1384 <returnvalue>double precision</returnvalue>
1385 </para>
1386 <para>
1387 Nearest integer less than or equal to argument
1388 </para>
1389 <para>
1390 <literal>floor(42.8)</literal>
1391 <returnvalue>42</returnvalue>
1392 </para>
1393 <para>
1394 <literal>floor(-42.8)</literal>
1395 <returnvalue>-43</returnvalue>
1396 </para></entry>
1397 </row>
1399 <row>
1400 <entry role="func_table_entry"><para role="func_signature">
1401 <indexterm>
1402 <primary>gcd</primary>
1403 </indexterm>
1404 <function>gcd</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> )
1405 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1406 </para>
1407 <para>
1408 Greatest common divisor (the largest positive number that divides both
1409 inputs with no remainder); returns <literal>0</literal> if both inputs
1410 are zero; available for <type>integer</type>, <type>bigint</type>,
1411 and <type>numeric</type>
1412 </para>
1413 <para>
1414 <literal>gcd(1071, 462)</literal>
1415 <returnvalue>21</returnvalue>
1416 </para></entry>
1417 </row>
1419 <row>
1420 <entry role="func_table_entry"><para role="func_signature">
1421 <indexterm>
1422 <primary>lcm</primary>
1423 </indexterm>
1424 <function>lcm</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> )
1425 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1426 </para>
1427 <para>
1428 Least common multiple (the smallest strictly positive number that is
1429 an integral multiple of both inputs); returns <literal>0</literal> if
1430 either input is zero; available for <type>integer</type>,
1431 <type>bigint</type>, and <type>numeric</type>
1432 </para>
1433 <para>
1434 <literal>lcm(1071, 462)</literal>
1435 <returnvalue>23562</returnvalue>
1436 </para></entry>
1437 </row>
1439 <row>
1440 <entry role="func_table_entry"><para role="func_signature">
1441 <indexterm>
1442 <primary>ln</primary>
1443 </indexterm>
1444 <function>ln</function> ( <type>numeric</type> )
1445 <returnvalue>numeric</returnvalue>
1446 </para>
1447 <para role="func_signature">
1448 <function>ln</function> ( <type>double precision</type> )
1449 <returnvalue>double precision</returnvalue>
1450 </para>
1451 <para>
1452 Natural logarithm
1453 </para>
1454 <para>
1455 <literal>ln(2.0)</literal>
1456 <returnvalue>0.6931471805599453</returnvalue>
1457 </para></entry>
1458 </row>
1460 <row>
1461 <entry role="func_table_entry"><para role="func_signature">
1462 <indexterm>
1463 <primary>log</primary>
1464 </indexterm>
1465 <function>log</function> ( <type>numeric</type> )
1466 <returnvalue>numeric</returnvalue>
1467 </para>
1468 <para role="func_signature">
1469 <function>log</function> ( <type>double precision</type> )
1470 <returnvalue>double precision</returnvalue>
1471 </para>
1472 <para>
1473 Base 10 logarithm
1474 </para>
1475 <para>
1476 <literal>log(100)</literal>
1477 <returnvalue>2</returnvalue>
1478 </para></entry>
1479 </row>
1481 <row>
1482 <entry role="func_table_entry"><para role="func_signature">
1483 <indexterm>
1484 <primary>log10</primary>
1485 </indexterm>
1486 <function>log10</function> ( <type>numeric</type> )
1487 <returnvalue>numeric</returnvalue>
1488 </para>
1489 <para role="func_signature">
1490 <function>log10</function> ( <type>double precision</type> )
1491 <returnvalue>double precision</returnvalue>
1492 </para>
1493 <para>
1494 Base 10 logarithm (same as <function>log</function>)
1495 </para>
1496 <para>
1497 <literal>log10(1000)</literal>
1498 <returnvalue>3</returnvalue>
1499 </para></entry>
1500 </row>
1502 <row>
1503 <entry role="func_table_entry"><para role="func_signature">
1504 <function>log</function> ( <parameter>b</parameter> <type>numeric</type>,
1505 <parameter>x</parameter> <type>numeric</type> )
1506 <returnvalue>numeric</returnvalue>
1507 </para>
1508 <para>
1509 Logarithm of <parameter>x</parameter> to base <parameter>b</parameter>
1510 </para>
1511 <para>
1512 <literal>log(2.0, 64.0)</literal>
1513 <returnvalue>6.0000000000000000</returnvalue>
1514 </para></entry>
1515 </row>
1517 <row>
1518 <entry role="func_table_entry"><para role="func_signature">
1519 <indexterm>
1520 <primary>min_scale</primary>
1521 </indexterm>
1522 <function>min_scale</function> ( <type>numeric</type> )
1523 <returnvalue>integer</returnvalue>
1524 </para>
1525 <para>
1526 Minimum scale (number of fractional decimal digits) needed
1527 to represent the supplied value precisely
1528 </para>
1529 <para>
1530 <literal>min_scale(8.4100)</literal>
1531 <returnvalue>2</returnvalue>
1532 </para></entry>
1533 </row>
1535 <row>
1536 <entry role="func_table_entry"><para role="func_signature">
1537 <indexterm>
1538 <primary>mod</primary>
1539 </indexterm>
1540 <function>mod</function> ( <parameter>y</parameter> <replaceable>numeric_type</replaceable>,
1541 <parameter>x</parameter> <replaceable>numeric_type</replaceable> )
1542 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1543 </para>
1544 <para>
1545 Remainder of <parameter>y</parameter>/<parameter>x</parameter>;
1546 available for <type>smallint</type>, <type>integer</type>,
1547 <type>bigint</type>, and <type>numeric</type>
1548 </para>
1549 <para>
1550 <literal>mod(9, 4)</literal>
1551 <returnvalue>1</returnvalue>
1552 </para></entry>
1553 </row>
1555 <row>
1556 <entry role="func_table_entry"><para role="func_signature">
1557 <indexterm>
1558 <primary>pi</primary>
1559 </indexterm>
1560 <function>pi</function> ( )
1561 <returnvalue>double precision</returnvalue>
1562 </para>
1563 <para>
1564 Approximate value of <phrase role="symbol_font">&pi;</phrase>
1565 </para>
1566 <para>
1567 <literal>pi()</literal>
1568 <returnvalue>3.141592653589793</returnvalue>
1569 </para></entry>
1570 </row>
1572 <row>
1573 <entry role="func_table_entry"><para role="func_signature">
1574 <indexterm>
1575 <primary>power</primary>
1576 </indexterm>
1577 <function>power</function> ( <parameter>a</parameter> <type>numeric</type>,
1578 <parameter>b</parameter> <type>numeric</type> )
1579 <returnvalue>numeric</returnvalue>
1580 </para>
1581 <para role="func_signature">
1582 <function>power</function> ( <parameter>a</parameter> <type>double precision</type>,
1583 <parameter>b</parameter> <type>double precision</type> )
1584 <returnvalue>double precision</returnvalue>
1585 </para>
1586 <para>
1587 <parameter>a</parameter> raised to the power of <parameter>b</parameter>
1588 </para>
1589 <para>
1590 <literal>power(9, 3)</literal>
1591 <returnvalue>729</returnvalue>
1592 </para></entry>
1593 </row>
1595 <row>
1596 <entry role="func_table_entry"><para role="func_signature">
1597 <indexterm>
1598 <primary>radians</primary>
1599 </indexterm>
1600 <function>radians</function> ( <type>double precision</type> )
1601 <returnvalue>double precision</returnvalue>
1602 </para>
1603 <para>
1604 Converts degrees to radians
1605 </para>
1606 <para>
1607 <literal>radians(45.0)</literal>
1608 <returnvalue>0.7853981633974483</returnvalue>
1609 </para></entry>
1610 </row>
1612 <row>
1613 <entry role="func_table_entry"><para role="func_signature">
1614 <indexterm>
1615 <primary>round</primary>
1616 </indexterm>
1617 <function>round</function> ( <type>numeric</type> )
1618 <returnvalue>numeric</returnvalue>
1619 </para>
1620 <para role="func_signature">
1621 <function>round</function> ( <type>double precision</type> )
1622 <returnvalue>double precision</returnvalue>
1623 </para>
1624 <para>
1625 Rounds to nearest integer. For <type>numeric</type>, ties are
1626 broken by rounding away from zero. For <type>double precision</type>,
1627 the tie-breaking behavior is platform dependent, but
1628 <quote>round to nearest even</quote> is the most common rule.
1629 </para>
1630 <para>
1631 <literal>round(42.4)</literal>
1632 <returnvalue>42</returnvalue>
1633 </para></entry>
1634 </row>
1636 <row>
1637 <entry role="func_table_entry"><para role="func_signature">
1638 <function>round</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> )
1639 <returnvalue>numeric</returnvalue>
1640 </para>
1641 <para>
1642 Rounds <parameter>v</parameter> to <parameter>s</parameter> decimal
1643 places. Ties are broken by rounding away from zero.
1644 </para>
1645 <para>
1646 <literal>round(42.4382, 2)</literal>
1647 <returnvalue>42.44</returnvalue>
1648 </para>
1649 <para>
1650 <literal>round(1234.56, -1)</literal>
1651 <returnvalue>1230</returnvalue>
1652 </para></entry>
1653 </row>
1655 <row>
1656 <entry role="func_table_entry"><para role="func_signature">
1657 <indexterm>
1658 <primary>scale</primary>
1659 </indexterm>
1660 <function>scale</function> ( <type>numeric</type> )
1661 <returnvalue>integer</returnvalue>
1662 </para>
1663 <para>
1664 Scale of the argument (the number of decimal digits in the fractional part)
1665 </para>
1666 <para>
1667 <literal>scale(8.4100)</literal>
1668 <returnvalue>4</returnvalue>
1669 </para></entry>
1670 </row>
1672 <row>
1673 <entry role="func_table_entry"><para role="func_signature">
1674 <indexterm>
1675 <primary>sign</primary>
1676 </indexterm>
1677 <function>sign</function> ( <type>numeric</type> )
1678 <returnvalue>numeric</returnvalue>
1679 </para>
1680 <para role="func_signature">
1681 <function>sign</function> ( <type>double precision</type> )
1682 <returnvalue>double precision</returnvalue>
1683 </para>
1684 <para>
1685 Sign of the argument (-1, 0, or +1)
1686 </para>
1687 <para>
1688 <literal>sign(-8.4)</literal>
1689 <returnvalue>-1</returnvalue>
1690 </para></entry>
1691 </row>
1693 <row>
1694 <entry role="func_table_entry"><para role="func_signature">
1695 <indexterm>
1696 <primary>sqrt</primary>
1697 </indexterm>
1698 <function>sqrt</function> ( <type>numeric</type> )
1699 <returnvalue>numeric</returnvalue>
1700 </para>
1701 <para role="func_signature">
1702 <function>sqrt</function> ( <type>double precision</type> )
1703 <returnvalue>double precision</returnvalue>
1704 </para>
1705 <para>
1706 Square root
1707 </para>
1708 <para>
1709 <literal>sqrt(2)</literal>
1710 <returnvalue>1.4142135623730951</returnvalue>
1711 </para></entry>
1712 </row>
1714 <row>
1715 <entry role="func_table_entry"><para role="func_signature">
1716 <indexterm>
1717 <primary>trim_scale</primary>
1718 </indexterm>
1719 <function>trim_scale</function> ( <type>numeric</type> )
1720 <returnvalue>numeric</returnvalue>
1721 </para>
1722 <para>
1723 Reduces the value's scale (number of fractional decimal digits) by
1724 removing trailing zeroes
1725 </para>
1726 <para>
1727 <literal>trim_scale(8.4100)</literal>
1728 <returnvalue>8.41</returnvalue>
1729 </para></entry>
1730 </row>
1732 <row>
1733 <entry role="func_table_entry"><para role="func_signature">
1734 <indexterm>
1735 <primary>trunc</primary>
1736 </indexterm>
1737 <function>trunc</function> ( <type>numeric</type> )
1738 <returnvalue>numeric</returnvalue>
1739 </para>
1740 <para role="func_signature">
1741 <function>trunc</function> ( <type>double precision</type> )
1742 <returnvalue>double precision</returnvalue>
1743 </para>
1744 <para>
1745 Truncates to integer (towards zero)
1746 </para>
1747 <para>
1748 <literal>trunc(42.8)</literal>
1749 <returnvalue>42</returnvalue>
1750 </para>
1751 <para>
1752 <literal>trunc(-42.8)</literal>
1753 <returnvalue>-42</returnvalue>
1754 </para></entry>
1755 </row>
1757 <row>
1758 <entry role="func_table_entry"><para role="func_signature">
1759 <function>trunc</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> )
1760 <returnvalue>numeric</returnvalue>
1761 </para>
1762 <para>
1763 Truncates <parameter>v</parameter> to <parameter>s</parameter>
1764 decimal places
1765 </para>
1766 <para>
1767 <literal>trunc(42.4382, 2)</literal>
1768 <returnvalue>42.43</returnvalue>
1769 </para></entry>
1770 </row>
1772 <row>
1773 <entry role="func_table_entry"><para role="func_signature">
1774 <indexterm>
1775 <primary>width_bucket</primary>
1776 </indexterm>
1777 <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> )
1778 <returnvalue>integer</returnvalue>
1779 </para>
1780 <para role="func_signature">
1781 <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> )
1782 <returnvalue>integer</returnvalue>
1783 </para>
1784 <para>
1785 Returns the number of the bucket in
1786 which <parameter>operand</parameter> falls in a histogram
1787 having <parameter>count</parameter> equal-width buckets spanning the
1788 range <parameter>low</parameter> to <parameter>high</parameter>.
1789 Returns <literal>0</literal>
1790 or <literal><parameter>count</parameter>+1</literal> for an input
1791 outside that range.
1792 </para>
1793 <para>
1794 <literal>width_bucket(5.35, 0.024, 10.06, 5)</literal>
1795 <returnvalue>3</returnvalue>
1796 </para></entry>
1797 </row>
1799 <row>
1800 <entry role="func_table_entry"><para role="func_signature">
1801 <function>width_bucket</function> ( <parameter>operand</parameter> <type>anycompatible</type>, <parameter>thresholds</parameter> <type>anycompatiblearray</type> )
1802 <returnvalue>integer</returnvalue>
1803 </para>
1804 <para>
1805 Returns the number of the bucket in
1806 which <parameter>operand</parameter> falls given an array listing the
1807 lower bounds of the buckets. Returns <literal>0</literal> for an
1808 input less than the first lower
1809 bound. <parameter>operand</parameter> and the array elements can be
1810 of any type having standard comparison operators.
1811 The <parameter>thresholds</parameter> array <emphasis>must be
1812 sorted</emphasis>, smallest first, or unexpected results will be
1813 obtained.
1814 </para>
1815 <para>
1816 <literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])</literal>
1817 <returnvalue>2</returnvalue>
1818 </para></entry>
1819 </row>
1820 </tbody>
1821 </tgroup>
1822 </table>
1824 <para>
1825 <xref linkend="functions-math-random-table"/> shows functions for
1826 generating random numbers.
1827 </para>
1829 <table id="functions-math-random-table">
1830 <title>Random Functions</title>
1832 <tgroup cols="1">
1833 <thead>
1834 <row>
1835 <entry role="func_table_entry"><para role="func_signature">
1836 Function
1837 </para>
1838 <para>
1839 Description
1840 </para>
1841 <para>
1842 Example(s)
1843 </para></entry>
1844 </row>
1845 </thead>
1847 <tbody>
1848 <row>
1849 <entry role="func_table_entry"><para role="func_signature">
1850 <indexterm>
1851 <primary>random</primary>
1852 </indexterm>
1853 <function>random</function> ( )
1854 <returnvalue>double precision</returnvalue>
1855 </para>
1856 <para>
1857 Returns a random value in the range 0.0 &lt;= x &lt; 1.0
1858 </para>
1859 <para>
1860 <literal>random()</literal>
1861 <returnvalue>0.897124072839091</returnvalue>
1862 </para></entry>
1863 </row>
1865 <row>
1866 <entry role="func_table_entry"><para role="func_signature">
1867 <indexterm>
1868 <primary>random_normal</primary>
1869 </indexterm>
1871 <function>random_normal</function> (
1872 <optional> <parameter>mean</parameter> <type>double precision</type>
1873 <optional>, <parameter>stddev</parameter> <type>double precision</type> </optional></optional> )
1874 <returnvalue>double precision</returnvalue>
1875 </para>
1876 <para>
1877 Returns a random value from the normal distribution with the given
1878 parameters; <parameter>mean</parameter> defaults to 0.0
1879 and <parameter>stddev</parameter> defaults to 1.0
1880 </para>
1881 <para>
1882 <literal>random_normal(0.0, 1.0)</literal>
1883 <returnvalue>0.051285419</returnvalue>
1884 </para></entry>
1885 </row>
1887 <row>
1888 <entry role="func_table_entry"><para role="func_signature">
1889 <indexterm>
1890 <primary>setseed</primary>
1891 </indexterm>
1892 <function>setseed</function> ( <type>double precision</type> )
1893 <returnvalue>void</returnvalue>
1894 </para>
1895 <para>
1896 Sets the seed for subsequent <literal>random()</literal> and
1897 <literal>random_normal()</literal> calls;
1898 argument must be between -1.0 and 1.0, inclusive
1899 </para>
1900 <para>
1901 <literal>setseed(0.12345)</literal>
1902 </para></entry>
1903 </row>
1904 </tbody>
1905 </tgroup>
1906 </table>
1908 <para>
1909 The <function>random()</function> function uses a deterministic
1910 pseudo-random number generator.
1911 It is fast but not suitable for cryptographic
1912 applications; see the <xref linkend="pgcrypto"/> module for a more
1913 secure alternative.
1914 If <function>setseed()</function> is called, the series of results of
1915 subsequent <function>random()</function> calls in the current session
1916 can be repeated by re-issuing <function>setseed()</function> with the same
1917 argument.
1918 Without any prior <function>setseed()</function> call in the same
1919 session, the first <function>random()</function> call obtains a seed
1920 from a platform-dependent source of random bits.
1921 These remarks hold equally for <function>random_normal()</function>.
1922 </para>
1924 <para>
1925 <xref linkend="functions-math-trig-table"/> shows the
1926 available trigonometric functions. Each of these functions comes in
1927 two variants, one that measures angles in radians and one that
1928 measures angles in degrees.
1929 </para>
1931 <table id="functions-math-trig-table">
1932 <title>Trigonometric Functions</title>
1934 <tgroup cols="1">
1935 <thead>
1936 <row>
1937 <entry role="func_table_entry"><para role="func_signature">
1938 Function
1939 </para>
1940 <para>
1941 Description
1942 </para>
1943 <para>
1944 Example(s)
1945 </para></entry>
1946 </row>
1947 </thead>
1949 <tbody>
1950 <row>
1951 <entry role="func_table_entry"><para role="func_signature">
1952 <indexterm>
1953 <primary>acos</primary>
1954 </indexterm>
1955 <function>acos</function> ( <type>double precision</type> )
1956 <returnvalue>double precision</returnvalue>
1957 </para>
1958 <para>
1959 Inverse cosine, result in radians
1960 </para>
1961 <para>
1962 <literal>acos(1)</literal>
1963 <returnvalue>0</returnvalue>
1964 </para></entry>
1965 </row>
1967 <row>
1968 <entry role="func_table_entry"><para role="func_signature">
1969 <indexterm>
1970 <primary>acosd</primary>
1971 </indexterm>
1972 <function>acosd</function> ( <type>double precision</type> )
1973 <returnvalue>double precision</returnvalue>
1974 </para>
1975 <para>
1976 Inverse cosine, result in degrees
1977 </para>
1978 <para>
1979 <literal>acosd(0.5)</literal>
1980 <returnvalue>60</returnvalue>
1981 </para></entry>
1982 </row>
1984 <row>
1985 <entry role="func_table_entry"><para role="func_signature">
1986 <indexterm>
1987 <primary>asin</primary>
1988 </indexterm>
1989 <function>asin</function> ( <type>double precision</type> )
1990 <returnvalue>double precision</returnvalue>
1991 </para>
1992 <para>
1993 Inverse sine, result in radians
1994 </para>
1995 <para>
1996 <literal>asin(1)</literal>
1997 <returnvalue>1.5707963267948966</returnvalue>
1998 </para></entry>
1999 </row>
2001 <row>
2002 <entry role="func_table_entry"><para role="func_signature">
2003 <indexterm>
2004 <primary>asind</primary>
2005 </indexterm>
2006 <function>asind</function> ( <type>double precision</type> )
2007 <returnvalue>double precision</returnvalue>
2008 </para>
2009 <para>
2010 Inverse sine, result in degrees
2011 </para>
2012 <para>
2013 <literal>asind(0.5)</literal>
2014 <returnvalue>30</returnvalue>
2015 </para></entry>
2016 </row>
2018 <row>
2019 <entry role="func_table_entry"><para role="func_signature">
2020 <indexterm>
2021 <primary>atan</primary>
2022 </indexterm>
2023 <function>atan</function> ( <type>double precision</type> )
2024 <returnvalue>double precision</returnvalue>
2025 </para>
2026 <para>
2027 Inverse tangent, result in radians
2028 </para>
2029 <para>
2030 <literal>atan(1)</literal>
2031 <returnvalue>0.7853981633974483</returnvalue>
2032 </para></entry>
2033 </row>
2035 <row>
2036 <entry role="func_table_entry"><para role="func_signature">
2037 <indexterm>
2038 <primary>atand</primary>
2039 </indexterm>
2040 <function>atand</function> ( <type>double precision</type> )
2041 <returnvalue>double precision</returnvalue>
2042 </para>
2043 <para>
2044 Inverse tangent, result in degrees
2045 </para>
2046 <para>
2047 <literal>atand(1)</literal>
2048 <returnvalue>45</returnvalue>
2049 </para></entry>
2050 </row>
2052 <row>
2053 <entry role="func_table_entry"><para role="func_signature">
2054 <indexterm>
2055 <primary>atan2</primary>
2056 </indexterm>
2057 <function>atan2</function> ( <parameter>y</parameter> <type>double precision</type>,
2058 <parameter>x</parameter> <type>double precision</type> )
2059 <returnvalue>double precision</returnvalue>
2060 </para>
2061 <para>
2062 Inverse tangent of
2063 <parameter>y</parameter>/<parameter>x</parameter>,
2064 result in radians
2065 </para>
2066 <para>
2067 <literal>atan2(1, 0)</literal>
2068 <returnvalue>1.5707963267948966</returnvalue>
2069 </para></entry>
2070 </row>
2072 <row>
2073 <entry role="func_table_entry"><para role="func_signature">
2074 <indexterm>
2075 <primary>atan2d</primary>
2076 </indexterm>
2077 <function>atan2d</function> ( <parameter>y</parameter> <type>double precision</type>,
2078 <parameter>x</parameter> <type>double precision</type> )
2079 <returnvalue>double precision</returnvalue>
2080 </para>
2081 <para>
2082 Inverse tangent of
2083 <parameter>y</parameter>/<parameter>x</parameter>,
2084 result in degrees
2085 </para>
2086 <para>
2087 <literal>atan2d(1, 0)</literal>
2088 <returnvalue>90</returnvalue>
2089 </para></entry>
2090 </row>
2092 <row>
2093 <entry role="func_table_entry"><para role="func_signature">
2094 <indexterm>
2095 <primary>cos</primary>
2096 </indexterm>
2097 <function>cos</function> ( <type>double precision</type> )
2098 <returnvalue>double precision</returnvalue>
2099 </para>
2100 <para>
2101 Cosine, argument in radians
2102 </para>
2103 <para>
2104 <literal>cos(0)</literal>
2105 <returnvalue>1</returnvalue>
2106 </para></entry>
2107 </row>
2109 <row>
2110 <entry role="func_table_entry"><para role="func_signature">
2111 <indexterm>
2112 <primary>cosd</primary>
2113 </indexterm>
2114 <function>cosd</function> ( <type>double precision</type> )
2115 <returnvalue>double precision</returnvalue>
2116 </para>
2117 <para>
2118 Cosine, argument in degrees
2119 </para>
2120 <para>
2121 <literal>cosd(60)</literal>
2122 <returnvalue>0.5</returnvalue>
2123 </para></entry>
2124 </row>
2126 <row>
2127 <entry role="func_table_entry"><para role="func_signature">
2128 <indexterm>
2129 <primary>cot</primary>
2130 </indexterm>
2131 <function>cot</function> ( <type>double precision</type> )
2132 <returnvalue>double precision</returnvalue>
2133 </para>
2134 <para>
2135 Cotangent, argument in radians
2136 </para>
2137 <para>
2138 <literal>cot(0.5)</literal>
2139 <returnvalue>1.830487721712452</returnvalue>
2140 </para></entry>
2141 </row>
2143 <row>
2144 <entry role="func_table_entry"><para role="func_signature">
2145 <indexterm>
2146 <primary>cotd</primary>
2147 </indexterm>
2148 <function>cotd</function> ( <type>double precision</type> )
2149 <returnvalue>double precision</returnvalue>
2150 </para>
2151 <para>
2152 Cotangent, argument in degrees
2153 </para>
2154 <para>
2155 <literal>cotd(45)</literal>
2156 <returnvalue>1</returnvalue>
2157 </para></entry>
2158 </row>
2160 <row>
2161 <entry role="func_table_entry"><para role="func_signature">
2162 <indexterm>
2163 <primary>sin</primary>
2164 </indexterm>
2165 <function>sin</function> ( <type>double precision</type> )
2166 <returnvalue>double precision</returnvalue>
2167 </para>
2168 <para>
2169 Sine, argument in radians
2170 </para>
2171 <para>
2172 <literal>sin(1)</literal>
2173 <returnvalue>0.8414709848078965</returnvalue>
2174 </para></entry>
2175 </row>
2177 <row>
2178 <entry role="func_table_entry"><para role="func_signature">
2179 <indexterm>
2180 <primary>sind</primary>
2181 </indexterm>
2182 <function>sind</function> ( <type>double precision</type> )
2183 <returnvalue>double precision</returnvalue>
2184 </para>
2185 <para>
2186 Sine, argument in degrees
2187 </para>
2188 <para>
2189 <literal>sind(30)</literal>
2190 <returnvalue>0.5</returnvalue>
2191 </para></entry>
2192 </row>
2194 <row>
2195 <entry role="func_table_entry"><para role="func_signature">
2196 <indexterm>
2197 <primary>tan</primary>
2198 </indexterm>
2199 <function>tan</function> ( <type>double precision</type> )
2200 <returnvalue>double precision</returnvalue>
2201 </para>
2202 <para>
2203 Tangent, argument in radians
2204 </para>
2205 <para>
2206 <literal>tan(1)</literal>
2207 <returnvalue>1.5574077246549023</returnvalue>
2208 </para></entry>
2209 </row>
2211 <row>
2212 <entry role="func_table_entry"><para role="func_signature">
2213 <indexterm>
2214 <primary>tand</primary>
2215 </indexterm>
2216 <function>tand</function> ( <type>double precision</type> )
2217 <returnvalue>double precision</returnvalue>
2218 </para>
2219 <para>
2220 Tangent, argument in degrees
2221 </para>
2222 <para>
2223 <literal>tand(45)</literal>
2224 <returnvalue>1</returnvalue>
2225 </para></entry>
2226 </row>
2227 </tbody>
2228 </tgroup>
2229 </table>
2231 <note>
2232 <para>
2233 Another way to work with angles measured in degrees is to use the unit
2234 transformation functions <literal><function>radians()</function></literal>
2235 and <literal><function>degrees()</function></literal> shown earlier.
2236 However, using the degree-based trigonometric functions is preferred,
2237 as that way avoids round-off error for special cases such
2238 as <literal>sind(30)</literal>.
2239 </para>
2240 </note>
2242 <para>
2243 <xref linkend="functions-math-hyp-table"/> shows the
2244 available hyperbolic functions.
2245 </para>
2247 <table id="functions-math-hyp-table">
2248 <title>Hyperbolic Functions</title>
2250 <tgroup cols="1">
2251 <thead>
2252 <row>
2253 <entry role="func_table_entry"><para role="func_signature">
2254 Function
2255 </para>
2256 <para>
2257 Description
2258 </para>
2259 <para>
2260 Example(s)
2261 </para></entry>
2262 </row>
2263 </thead>
2265 <tbody>
2266 <row>
2267 <entry role="func_table_entry"><para role="func_signature">
2268 <indexterm>
2269 <primary>sinh</primary>
2270 </indexterm>
2271 <function>sinh</function> ( <type>double precision</type> )
2272 <returnvalue>double precision</returnvalue>
2273 </para>
2274 <para>
2275 Hyperbolic sine
2276 </para>
2277 <para>
2278 <literal>sinh(1)</literal>
2279 <returnvalue>1.1752011936438014</returnvalue>
2280 </para></entry>
2281 </row>
2283 <row>
2284 <entry role="func_table_entry"><para role="func_signature">
2285 <indexterm>
2286 <primary>cosh</primary>
2287 </indexterm>
2288 <function>cosh</function> ( <type>double precision</type> )
2289 <returnvalue>double precision</returnvalue>
2290 </para>
2291 <para>
2292 Hyperbolic cosine
2293 </para>
2294 <para>
2295 <literal>cosh(0)</literal>
2296 <returnvalue>1</returnvalue>
2297 </para></entry>
2298 </row>
2300 <row>
2301 <entry role="func_table_entry"><para role="func_signature">
2302 <indexterm>
2303 <primary>tanh</primary>
2304 </indexterm>
2305 <function>tanh</function> ( <type>double precision</type> )
2306 <returnvalue>double precision</returnvalue>
2307 </para>
2308 <para>
2309 Hyperbolic tangent
2310 </para>
2311 <para>
2312 <literal>tanh(1)</literal>
2313 <returnvalue>0.7615941559557649</returnvalue>
2314 </para></entry>
2315 </row>
2317 <row>
2318 <entry role="func_table_entry"><para role="func_signature">
2319 <indexterm>
2320 <primary>asinh</primary>
2321 </indexterm>
2322 <function>asinh</function> ( <type>double precision</type> )
2323 <returnvalue>double precision</returnvalue>
2324 </para>
2325 <para>
2326 Inverse hyperbolic sine
2327 </para>
2328 <para>
2329 <literal>asinh(1)</literal>
2330 <returnvalue>0.881373587019543</returnvalue>
2331 </para></entry>
2332 </row>
2334 <row>
2335 <entry role="func_table_entry"><para role="func_signature">
2336 <indexterm>
2337 <primary>acosh</primary>
2338 </indexterm>
2339 <function>acosh</function> ( <type>double precision</type> )
2340 <returnvalue>double precision</returnvalue>
2341 </para>
2342 <para>
2343 Inverse hyperbolic cosine
2344 </para>
2345 <para>
2346 <literal>acosh(1)</literal>
2347 <returnvalue>0</returnvalue>
2348 </para></entry>
2349 </row>
2351 <row>
2352 <entry role="func_table_entry"><para role="func_signature">
2353 <indexterm>
2354 <primary>atanh</primary>
2355 </indexterm>
2356 <function>atanh</function> ( <type>double precision</type> )
2357 <returnvalue>double precision</returnvalue>
2358 </para>
2359 <para>
2360 Inverse hyperbolic tangent
2361 </para>
2362 <para>
2363 <literal>atanh(0.5)</literal>
2364 <returnvalue>0.5493061443340548</returnvalue>
2365 </para></entry>
2366 </row>
2367 </tbody>
2368 </tgroup>
2369 </table>
2371 </sect1>
2374 <sect1 id="functions-string">
2375 <title>String Functions and Operators</title>
2377 <para>
2378 This section describes functions and operators for examining and
2379 manipulating string values. Strings in this context include values
2380 of the types <type>character</type>, <type>character varying</type>,
2381 and <type>text</type>. Except where noted, these functions and operators
2382 are declared to accept and return type <type>text</type>. They will
2383 interchangeably accept <type>character varying</type> arguments.
2384 Values of type <type>character</type> will be converted
2385 to <type>text</type> before the function or operator is applied, resulting
2386 in stripping any trailing spaces in the <type>character</type> value.
2387 </para>
2389 <para>
2390 <acronym>SQL</acronym> defines some string functions that use
2391 key words, rather than commas, to separate
2392 arguments. Details are in
2393 <xref linkend="functions-string-sql"/>.
2394 <productname>PostgreSQL</productname> also provides versions of these functions
2395 that use the regular function invocation syntax
2396 (see <xref linkend="functions-string-other"/>).
2397 </para>
2399 <note>
2400 <para>
2401 The string concatenation operator (<literal>||</literal>) will accept
2402 non-string input, so long as at least one input is of string type, as shown
2403 in <xref linkend="functions-string-sql"/>. For other cases, inserting an
2404 explicit coercion to <type>text</type> can be used to have non-string input
2405 accepted.
2406 </para>
2407 </note>
2409 <table id="functions-string-sql">
2410 <title><acronym>SQL</acronym> String Functions and Operators</title>
2411 <tgroup cols="1">
2412 <thead>
2413 <row>
2414 <entry role="func_table_entry"><para role="func_signature">
2415 Function/Operator
2416 </para>
2417 <para>
2418 Description
2419 </para>
2420 <para>
2421 Example(s)
2422 </para></entry>
2423 </row>
2424 </thead>
2426 <tbody>
2427 <row>
2428 <entry role="func_table_entry"><para role="func_signature">
2429 <indexterm>
2430 <primary>character string</primary>
2431 <secondary>concatenation</secondary>
2432 </indexterm>
2433 <type>text</type> <literal>||</literal> <type>text</type>
2434 <returnvalue>text</returnvalue>
2435 </para>
2436 <para>
2437 Concatenates the two strings.
2438 </para>
2439 <para>
2440 <literal>'Post' || 'greSQL'</literal>
2441 <returnvalue>PostgreSQL</returnvalue>
2442 </para></entry>
2443 </row>
2445 <row>
2446 <entry role="func_table_entry"><para role="func_signature">
2447 <type>text</type> <literal>||</literal> <type>anynonarray</type>
2448 <returnvalue>text</returnvalue>
2449 </para>
2450 <para role="func_signature">
2451 <type>anynonarray</type> <literal>||</literal> <type>text</type>
2452 <returnvalue>text</returnvalue>
2453 </para>
2454 <para>
2455 Converts the non-string input to text, then concatenates the two
2456 strings. (The non-string input cannot be of an array type, because
2457 that would create ambiguity with the array <literal>||</literal>
2458 operators. If you want to concatenate an array's text equivalent,
2459 cast it to <type>text</type> explicitly.)
2460 </para>
2461 <para>
2462 <literal>'Value: ' || 42</literal>
2463 <returnvalue>Value: 42</returnvalue>
2464 </para></entry>
2465 </row>
2467 <row>
2468 <entry role="func_table_entry"><para role="func_signature">
2469 <indexterm>
2470 <primary>btrim</primary>
2471 </indexterm>
2472 <function>btrim</function> ( <parameter>string</parameter> <type>text</type>
2473 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2474 <returnvalue>text</returnvalue>
2475 </para>
2476 <para>
2477 Removes the longest string containing only characters
2478 in <parameter>characters</parameter> (a space by default)
2479 from the start and end of <parameter>string</parameter>.
2480 </para>
2481 <para>
2482 <literal>btrim('xyxtrimyyx', 'xyz')</literal>
2483 <returnvalue>trim</returnvalue>
2484 </para></entry>
2485 </row>
2487 <row>
2488 <entry role="func_table_entry"><para role="func_signature">
2489 <indexterm>
2490 <primary>normalized</primary>
2491 </indexterm>
2492 <indexterm>
2493 <primary>Unicode normalization</primary>
2494 </indexterm>
2495 <type>text</type> <literal>IS</literal> <optional><literal>NOT</literal></optional> <optional><parameter>form</parameter></optional> <literal>NORMALIZED</literal>
2496 <returnvalue>boolean</returnvalue>
2497 </para>
2498 <para>
2499 Checks whether the string is in the specified Unicode normalization
2500 form. The optional <parameter>form</parameter> key word specifies the
2501 form: <literal>NFC</literal> (the default), <literal>NFD</literal>,
2502 <literal>NFKC</literal>, or <literal>NFKD</literal>. This expression can
2503 only be used when the server encoding is <literal>UTF8</literal>. Note
2504 that checking for normalization using this expression is often faster
2505 than normalizing possibly already normalized strings.
2506 </para>
2507 <para>
2508 <literal>U&amp;'\0061\0308bc' IS NFD NORMALIZED</literal>
2509 <returnvalue>t</returnvalue>
2510 </para></entry>
2511 </row>
2513 <row>
2514 <entry role="func_table_entry"><para role="func_signature">
2515 <indexterm>
2516 <primary>bit_length</primary>
2517 </indexterm>
2518 <function>bit_length</function> ( <type>text</type> )
2519 <returnvalue>integer</returnvalue>
2520 </para>
2521 <para>
2522 Returns number of bits in the string (8
2523 times the <function>octet_length</function>).
2524 </para>
2525 <para>
2526 <literal>bit_length('jose')</literal>
2527 <returnvalue>32</returnvalue>
2528 </para></entry>
2529 </row>
2531 <row>
2532 <entry role="func_table_entry"><para role="func_signature">
2533 <indexterm>
2534 <primary>char_length</primary>
2535 </indexterm>
2536 <indexterm>
2537 <primary>character string</primary>
2538 <secondary>length</secondary>
2539 </indexterm>
2540 <indexterm>
2541 <primary>length</primary>
2542 <secondary sortas="character string">of a character string</secondary>
2543 <see>character string, length</see>
2544 </indexterm>
2545 <function>char_length</function> ( <type>text</type> )
2546 <returnvalue>integer</returnvalue>
2547 </para>
2548 <para role="func_signature">
2549 <indexterm>
2550 <primary>character_length</primary>
2551 </indexterm>
2552 <function>character_length</function> ( <type>text</type> )
2553 <returnvalue>integer</returnvalue>
2554 </para>
2555 <para>
2556 Returns number of characters in the string.
2557 </para>
2558 <para>
2559 <literal>char_length('jos&eacute;')</literal>
2560 <returnvalue>4</returnvalue>
2561 </para></entry>
2562 </row>
2564 <row>
2565 <entry role="func_table_entry"><para role="func_signature">
2566 <indexterm>
2567 <primary>lower</primary>
2568 </indexterm>
2569 <function>lower</function> ( <type>text</type> )
2570 <returnvalue>text</returnvalue>
2571 </para>
2572 <para>
2573 Converts the string to all lower case, according to the rules of the
2574 database's locale.
2575 </para>
2576 <para>
2577 <literal>lower('TOM')</literal>
2578 <returnvalue>tom</returnvalue>
2579 </para></entry>
2580 </row>
2582 <row>
2583 <entry role="func_table_entry"><para role="func_signature">
2584 <indexterm>
2585 <primary>lpad</primary>
2586 </indexterm>
2587 <function>lpad</function> ( <parameter>string</parameter> <type>text</type>,
2588 <parameter>length</parameter> <type>integer</type>
2589 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
2590 <returnvalue>text</returnvalue>
2591 </para>
2592 <para>
2593 Extends the <parameter>string</parameter> to length
2594 <parameter>length</parameter> by prepending the characters
2595 <parameter>fill</parameter> (a space by default). If the
2596 <parameter>string</parameter> is already longer than
2597 <parameter>length</parameter> then it is truncated (on the right).
2598 </para>
2599 <para>
2600 <literal>lpad('hi', 5, 'xy')</literal>
2601 <returnvalue>xyxhi</returnvalue>
2602 </para></entry>
2603 </row>
2605 <row>
2606 <entry role="func_table_entry"><para role="func_signature">
2607 <indexterm>
2608 <primary>ltrim</primary>
2609 </indexterm>
2610 <function>ltrim</function> ( <parameter>string</parameter> <type>text</type>
2611 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2612 <returnvalue>text</returnvalue>
2613 </para>
2614 <para>
2615 Removes the longest string containing only characters in
2616 <parameter>characters</parameter> (a space by default) from the start of
2617 <parameter>string</parameter>.
2618 </para>
2619 <para>
2620 <literal>ltrim('zzzytest', 'xyz')</literal>
2621 <returnvalue>test</returnvalue>
2622 </para></entry>
2623 </row>
2625 <row>
2626 <entry role="func_table_entry"><para role="func_signature">
2627 <indexterm>
2628 <primary>normalize</primary>
2629 </indexterm>
2630 <indexterm>
2631 <primary>Unicode normalization</primary>
2632 </indexterm>
2633 <function>normalize</function> ( <type>text</type>
2634 <optional>, <parameter>form</parameter> </optional> )
2635 <returnvalue>text</returnvalue>
2636 </para>
2637 <para>
2638 Converts the string to the specified Unicode
2639 normalization form. The optional <parameter>form</parameter> key word
2640 specifies the form: <literal>NFC</literal> (the default),
2641 <literal>NFD</literal>, <literal>NFKC</literal>, or
2642 <literal>NFKD</literal>. This function can only be used when the
2643 server encoding is <literal>UTF8</literal>.
2644 </para>
2645 <para>
2646 <literal>normalize(U&amp;'\0061\0308bc', NFC)</literal>
2647 <returnvalue>U&amp;'\00E4bc'</returnvalue>
2648 </para></entry>
2649 </row>
2651 <row>
2652 <entry role="func_table_entry"><para role="func_signature">
2653 <indexterm>
2654 <primary>octet_length</primary>
2655 </indexterm>
2656 <function>octet_length</function> ( <type>text</type> )
2657 <returnvalue>integer</returnvalue>
2658 </para>
2659 <para>
2660 Returns number of bytes in the string.
2661 </para>
2662 <para>
2663 <literal>octet_length('jos&eacute;')</literal>
2664 <returnvalue>5</returnvalue> (if server encoding is UTF8)
2665 </para></entry>
2666 </row>
2668 <row>
2669 <entry role="func_table_entry"><para role="func_signature">
2670 <indexterm>
2671 <primary>octet_length</primary>
2672 </indexterm>
2673 <function>octet_length</function> ( <type>character</type> )
2674 <returnvalue>integer</returnvalue>
2675 </para>
2676 <para>
2677 Returns number of bytes in the string. Since this version of the
2678 function accepts type <type>character</type> directly, it will not
2679 strip trailing spaces.
2680 </para>
2681 <para>
2682 <literal>octet_length('abc '::character(4))</literal>
2683 <returnvalue>4</returnvalue>
2684 </para></entry>
2685 </row>
2687 <row>
2688 <entry role="func_table_entry"><para role="func_signature">
2689 <indexterm>
2690 <primary>overlay</primary>
2691 </indexterm>
2692 <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> )
2693 <returnvalue>text</returnvalue>
2694 </para>
2695 <para>
2696 Replaces the substring of <parameter>string</parameter> that starts at
2697 the <parameter>start</parameter>'th character and extends
2698 for <parameter>count</parameter> characters
2699 with <parameter>newsubstring</parameter>.
2700 If <parameter>count</parameter> is omitted, it defaults to the length
2701 of <parameter>newsubstring</parameter>.
2702 </para>
2703 <para>
2704 <literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal>
2705 <returnvalue>Thomas</returnvalue>
2706 </para></entry>
2707 </row>
2709 <row>
2710 <entry role="func_table_entry"><para role="func_signature">
2711 <indexterm>
2712 <primary>position</primary>
2713 </indexterm>
2714 <function>position</function> ( <parameter>substring</parameter> <type>text</type> <literal>IN</literal> <parameter>string</parameter> <type>text</type> )
2715 <returnvalue>integer</returnvalue>
2716 </para>
2717 <para>
2718 Returns first starting index of the specified
2719 <parameter>substring</parameter> within
2720 <parameter>string</parameter>, or zero if it's not present.
2721 </para>
2722 <para>
2723 <literal>position('om' in 'Thomas')</literal>
2724 <returnvalue>3</returnvalue>
2725 </para></entry>
2726 </row>
2728 <row>
2729 <entry role="func_table_entry"><para role="func_signature">
2730 <indexterm>
2731 <primary>rpad</primary>
2732 </indexterm>
2733 <function>rpad</function> ( <parameter>string</parameter> <type>text</type>,
2734 <parameter>length</parameter> <type>integer</type>
2735 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
2736 <returnvalue>text</returnvalue>
2737 </para>
2738 <para>
2739 Extends the <parameter>string</parameter> to length
2740 <parameter>length</parameter> by appending the characters
2741 <parameter>fill</parameter> (a space by default). If the
2742 <parameter>string</parameter> is already longer than
2743 <parameter>length</parameter> then it is truncated.
2744 </para>
2745 <para>
2746 <literal>rpad('hi', 5, 'xy')</literal>
2747 <returnvalue>hixyx</returnvalue>
2748 </para></entry>
2749 </row>
2751 <row>
2752 <entry role="func_table_entry"><para role="func_signature">
2753 <indexterm>
2754 <primary>rtrim</primary>
2755 </indexterm>
2756 <function>rtrim</function> ( <parameter>string</parameter> <type>text</type>
2757 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2758 <returnvalue>text</returnvalue>
2759 </para>
2760 <para>
2761 Removes the longest string containing only characters in
2762 <parameter>characters</parameter> (a space by default) from the end of
2763 <parameter>string</parameter>.
2764 </para>
2765 <para>
2766 <literal>rtrim('testxxzx', 'xyz')</literal>
2767 <returnvalue>test</returnvalue>
2768 </para></entry>
2769 </row>
2771 <row>
2772 <entry role="func_table_entry"><para role="func_signature">
2773 <indexterm>
2774 <primary>substring</primary>
2775 </indexterm>
2776 <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> )
2777 <returnvalue>text</returnvalue>
2778 </para>
2779 <para>
2780 Extracts the substring of <parameter>string</parameter> starting at
2781 the <parameter>start</parameter>'th character if that is specified,
2782 and stopping after <parameter>count</parameter> characters if that is
2783 specified. Provide at least one of <parameter>start</parameter>
2784 and <parameter>count</parameter>.
2785 </para>
2786 <para>
2787 <literal>substring('Thomas' from 2 for 3)</literal>
2788 <returnvalue>hom</returnvalue>
2789 </para>
2790 <para>
2791 <literal>substring('Thomas' from 3)</literal>
2792 <returnvalue>omas</returnvalue>
2793 </para>
2794 <para>
2795 <literal>substring('Thomas' for 2)</literal>
2796 <returnvalue>Th</returnvalue>
2797 </para></entry>
2798 </row>
2800 <row>
2801 <entry role="func_table_entry"><para role="func_signature">
2802 <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>FROM</literal> <parameter>pattern</parameter> <type>text</type> )
2803 <returnvalue>text</returnvalue>
2804 </para>
2805 <para>
2806 Extracts the first substring matching POSIX regular expression; see
2807 <xref linkend="functions-posix-regexp"/>.
2808 </para>
2809 <para>
2810 <literal>substring('Thomas' from '...$')</literal>
2811 <returnvalue>mas</returnvalue>
2812 </para></entry>
2813 </row>
2815 <row>
2816 <entry role="func_table_entry"><para role="func_signature">
2817 <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> )
2818 <returnvalue>text</returnvalue>
2819 </para>
2820 <para role="func_signature">
2821 <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> )
2822 <returnvalue>text</returnvalue>
2823 </para>
2824 <para>
2825 Extracts the first substring matching <acronym>SQL</acronym> regular expression;
2826 see <xref linkend="functions-similarto-regexp"/>. The first form has
2827 been specified since SQL:2003; the second form was only in SQL:1999
2828 and should be considered obsolete.
2829 </para>
2830 <para>
2831 <literal>substring('Thomas' similar '%#"o_a#"_' escape '#')</literal>
2832 <returnvalue>oma</returnvalue>
2833 </para></entry>
2834 </row>
2836 <row>
2837 <entry role="func_table_entry"><para role="func_signature">
2838 <indexterm>
2839 <primary>trim</primary>
2840 </indexterm>
2841 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
2842 <optional> <parameter>characters</parameter> <type>text</type> </optional> <literal>FROM</literal>
2843 <parameter>string</parameter> <type>text</type> )
2844 <returnvalue>text</returnvalue>
2845 </para>
2846 <para>
2847 Removes the longest string containing only characters in
2848 <parameter>characters</parameter> (a space by default) from the
2849 start, end, or both ends (<literal>BOTH</literal> is the default)
2850 of <parameter>string</parameter>.
2851 </para>
2852 <para>
2853 <literal>trim(both 'xyz' from 'yxTomxx')</literal>
2854 <returnvalue>Tom</returnvalue>
2855 </para></entry>
2856 </row>
2858 <row>
2859 <entry role="func_table_entry"><para role="func_signature">
2860 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
2861 <parameter>string</parameter> <type>text</type> <optional>,
2862 <parameter>characters</parameter> <type>text</type> </optional> )
2863 <returnvalue>text</returnvalue>
2864 </para>
2865 <para>
2866 This is a non-standard syntax for <function>trim()</function>.
2867 </para>
2868 <para>
2869 <literal>trim(both from 'yxTomxx', 'xyz')</literal>
2870 <returnvalue>Tom</returnvalue>
2871 </para></entry>
2872 </row>
2874 <row>
2875 <entry role="func_table_entry"><para role="func_signature">
2876 <indexterm>
2877 <primary>unicode_assigned</primary>
2878 </indexterm>
2879 <function>unicode_assigned</function> ( <type>text</type> )
2880 <returnvalue>text</returnvalue>
2881 </para>
2882 <para>
2883 Returns <literal>true</literal> if all characters in the string are
2884 assigned Unicode codepoints; <literal>false</literal> otherwise. This
2885 function can only be used when the server encoding is
2886 <literal>UTF8</literal>.
2887 </para></entry>
2888 </row>
2890 <row>
2891 <entry role="func_table_entry"><para role="func_signature">
2892 <indexterm>
2893 <primary>upper</primary>
2894 </indexterm>
2895 <function>upper</function> ( <type>text</type> )
2896 <returnvalue>text</returnvalue>
2897 </para>
2898 <para>
2899 Converts the string to all upper case, according to the rules of the
2900 database's locale.
2901 </para>
2902 <para>
2903 <literal>upper('tom')</literal>
2904 <returnvalue>TOM</returnvalue>
2905 </para></entry>
2906 </row>
2907 </tbody>
2908 </tgroup>
2909 </table>
2911 <para>
2912 Additional string manipulation functions and operators are available
2913 and are listed in <xref linkend="functions-string-other"/>. (Some of
2914 these are used internally to implement
2915 the <acronym>SQL</acronym>-standard string functions listed in
2916 <xref linkend="functions-string-sql"/>.)
2917 There are also pattern-matching operators, which are described in
2918 <xref linkend="functions-matching"/>, and operators for full-text
2919 search, which are described in <xref linkend="textsearch"/>.
2920 </para>
2922 <table id="functions-string-other">
2923 <title>Other String Functions and Operators</title>
2924 <tgroup cols="1">
2925 <thead>
2926 <row>
2927 <entry role="func_table_entry"><para role="func_signature">
2928 Function/Operator
2929 </para>
2930 <para>
2931 Description
2932 </para>
2933 <para>
2934 Example(s)
2935 </para></entry>
2936 </row>
2937 </thead>
2939 <tbody>
2940 <row>
2941 <entry role="func_table_entry"><para role="func_signature">
2942 <indexterm>
2943 <primary>character string</primary>
2944 <secondary>prefix test</secondary>
2945 </indexterm>
2946 <type>text</type> <literal>^@</literal> <type>text</type>
2947 <returnvalue>boolean</returnvalue>
2948 </para>
2949 <para>
2950 Returns true if the first string starts with the second string
2951 (equivalent to the <function>starts_with()</function> function).
2952 </para>
2953 <para>
2954 <literal>'alphabet' ^@ 'alph'</literal>
2955 <returnvalue>t</returnvalue>
2956 </para></entry>
2957 </row>
2959 <row>
2960 <entry role="func_table_entry"><para role="func_signature">
2961 <indexterm>
2962 <primary>ascii</primary>
2963 </indexterm>
2964 <function>ascii</function> ( <type>text</type> )
2965 <returnvalue>integer</returnvalue>
2966 </para>
2967 <para>
2968 Returns the numeric code of the first character of the argument.
2969 In <acronym>UTF8</acronym> encoding, returns the Unicode code point
2970 of the character. In other multibyte encodings, the argument must
2971 be an <acronym>ASCII</acronym> character.
2972 </para>
2973 <para>
2974 <literal>ascii('x')</literal>
2975 <returnvalue>120</returnvalue>
2976 </para></entry>
2977 </row>
2979 <row>
2980 <entry role="func_table_entry"><para role="func_signature">
2981 <indexterm>
2982 <primary>chr</primary>
2983 </indexterm>
2984 <function>chr</function> ( <type>integer</type> )
2985 <returnvalue>text</returnvalue>
2986 </para>
2987 <para>
2988 Returns the character with the given code. In <acronym>UTF8</acronym>
2989 encoding the argument is treated as a Unicode code point. In other
2990 multibyte encodings the argument must designate
2991 an <acronym>ASCII</acronym> character. <literal>chr(0)</literal> is
2992 disallowed because text data types cannot store that character.
2993 </para>
2994 <para>
2995 <literal>chr(65)</literal>
2996 <returnvalue>A</returnvalue>
2997 </para></entry>
2998 </row>
3000 <row>
3001 <entry role="func_table_entry"><para role="func_signature">
3002 <indexterm>
3003 <primary>concat</primary>
3004 </indexterm>
3005 <function>concat</function> ( <parameter>val1</parameter> <type>"any"</type>
3006 [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] )
3007 <returnvalue>text</returnvalue>
3008 </para>
3009 <para>
3010 Concatenates the text representations of all the arguments.
3011 NULL arguments are ignored.
3012 </para>
3013 <para>
3014 <literal>concat('abcde', 2, NULL, 22)</literal>
3015 <returnvalue>abcde222</returnvalue>
3016 </para></entry>
3017 </row>
3019 <row>
3020 <entry role="func_table_entry"><para role="func_signature">
3021 <indexterm>
3022 <primary>concat_ws</primary>
3023 </indexterm>
3024 <function>concat_ws</function> ( <parameter>sep</parameter> <type>text</type>,
3025 <parameter>val1</parameter> <type>"any"</type>
3026 [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] )
3027 <returnvalue>text</returnvalue>
3028 </para>
3029 <para>
3030 Concatenates all but the first argument, with separators. The first
3031 argument is used as the separator string, and should not be NULL.
3032 Other NULL arguments are ignored.
3033 </para>
3034 <para>
3035 <literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal>
3036 <returnvalue>abcde,2,22</returnvalue>
3037 </para></entry>
3038 </row>
3040 <row>
3041 <entry role="func_table_entry"><para role="func_signature">
3042 <indexterm>
3043 <primary>format</primary>
3044 </indexterm>
3045 <function>format</function> ( <parameter>formatstr</parameter> <type>text</type>
3046 [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ] )
3047 <returnvalue>text</returnvalue>
3048 </para>
3049 <para>
3050 Formats arguments according to a format string;
3051 see <xref linkend="functions-string-format"/>.
3052 This function is similar to the C function <function>sprintf</function>.
3053 </para>
3054 <para>
3055 <literal>format('Hello %s, %1$s', 'World')</literal>
3056 <returnvalue>Hello World, World</returnvalue>
3057 </para></entry>
3058 </row>
3060 <row>
3061 <entry role="func_table_entry"><para role="func_signature">
3062 <indexterm>
3063 <primary>initcap</primary>
3064 </indexterm>
3065 <function>initcap</function> ( <type>text</type> )
3066 <returnvalue>text</returnvalue>
3067 </para>
3068 <para>
3069 Converts the first letter of each word to upper case and the
3070 rest to lower case. Words are sequences of alphanumeric
3071 characters separated by non-alphanumeric characters.
3072 </para>
3073 <para>
3074 <literal>initcap('hi THOMAS')</literal>
3075 <returnvalue>Hi Thomas</returnvalue>
3076 </para></entry>
3077 </row>
3079 <row>
3080 <entry role="func_table_entry"><para role="func_signature">
3081 <indexterm>
3082 <primary>left</primary>
3083 </indexterm>
3084 <function>left</function> ( <parameter>string</parameter> <type>text</type>,
3085 <parameter>n</parameter> <type>integer</type> )
3086 <returnvalue>text</returnvalue>
3087 </para>
3088 <para>
3089 Returns first <parameter>n</parameter> characters in the
3090 string, or when <parameter>n</parameter> is negative, returns
3091 all but last |<parameter>n</parameter>| characters.
3092 </para>
3093 <para>
3094 <literal>left('abcde', 2)</literal>
3095 <returnvalue>ab</returnvalue>
3096 </para></entry>
3097 </row>
3099 <row>
3100 <entry role="func_table_entry"><para role="func_signature">
3101 <indexterm>
3102 <primary>length</primary>
3103 </indexterm>
3104 <function>length</function> ( <type>text</type> )
3105 <returnvalue>integer</returnvalue>
3106 </para>
3107 <para>
3108 Returns the number of characters in the string.
3109 </para>
3110 <para>
3111 <literal>length('jose')</literal>
3112 <returnvalue>4</returnvalue>
3113 </para></entry>
3114 </row>
3116 <row>
3117 <entry role="func_table_entry"><para role="func_signature">
3118 <indexterm>
3119 <primary>md5</primary>
3120 </indexterm>
3121 <function>md5</function> ( <type>text</type> )
3122 <returnvalue>text</returnvalue>
3123 </para>
3124 <para>
3125 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
3126 the argument, with the result written in hexadecimal.
3127 </para>
3128 <para>
3129 <literal>md5('abc')</literal>
3130 <returnvalue>900150983cd24fb0&zwsp;d6963f7d28e17f72</returnvalue>
3131 </para></entry>
3132 </row>
3134 <row>
3135 <entry role="func_table_entry"><para role="func_signature">
3136 <indexterm>
3137 <primary>parse_ident</primary>
3138 </indexterm>
3139 <function>parse_ident</function> ( <parameter>qualified_identifier</parameter> <type>text</type>
3140 [, <parameter>strict_mode</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>true</literal> ] )
3141 <returnvalue>text[]</returnvalue>
3142 </para>
3143 <para>
3144 Splits <parameter>qualified_identifier</parameter> into an array of
3145 identifiers, removing any quoting of individual identifiers. By
3146 default, extra characters after the last identifier are considered an
3147 error; but if the second parameter is <literal>false</literal>, then such
3148 extra characters are ignored. (This behavior is useful for parsing
3149 names for objects like functions.) Note that this function does not
3150 truncate over-length identifiers. If you want truncation you can cast
3151 the result to <type>name[]</type>.
3152 </para>
3153 <para>
3154 <literal>parse_ident('"SomeSchema".someTable')</literal>
3155 <returnvalue>{SomeSchema,sometable}</returnvalue>
3156 </para></entry>
3157 </row>
3159 <row>
3160 <entry role="func_table_entry"><para role="func_signature">
3161 <indexterm>
3162 <primary>pg_client_encoding</primary>
3163 </indexterm>
3164 <function>pg_client_encoding</function> ( )
3165 <returnvalue>name</returnvalue>
3166 </para>
3167 <para>
3168 Returns current client encoding name.
3169 </para>
3170 <para>
3171 <literal>pg_client_encoding()</literal>
3172 <returnvalue>UTF8</returnvalue>
3173 </para></entry>
3174 </row>
3176 <row>
3177 <entry role="func_table_entry"><para role="func_signature">
3178 <indexterm>
3179 <primary>quote_ident</primary>
3180 </indexterm>
3181 <function>quote_ident</function> ( <type>text</type> )
3182 <returnvalue>text</returnvalue>
3183 </para>
3184 <para>
3185 Returns the given string suitably quoted to be used as an identifier
3186 in an <acronym>SQL</acronym> statement string.
3187 Quotes are added only if necessary (i.e., if the string contains
3188 non-identifier characters or would be case-folded).
3189 Embedded quotes are properly doubled.
3190 See also <xref linkend="plpgsql-quote-literal-example"/>.
3191 </para>
3192 <para>
3193 <literal>quote_ident('Foo bar')</literal>
3194 <returnvalue>"Foo bar"</returnvalue>
3195 </para></entry>
3196 </row>
3198 <row>
3199 <entry role="func_table_entry"><para role="func_signature">
3200 <indexterm>
3201 <primary>quote_literal</primary>
3202 </indexterm>
3203 <function>quote_literal</function> ( <type>text</type> )
3204 <returnvalue>text</returnvalue>
3205 </para>
3206 <para>
3207 Returns the given string suitably quoted to be used as a string literal
3208 in an <acronym>SQL</acronym> statement string.
3209 Embedded single-quotes and backslashes are properly doubled.
3210 Note that <function>quote_literal</function> returns null on null
3211 input; if the argument might be null,
3212 <function>quote_nullable</function> is often more suitable.
3213 See also <xref linkend="plpgsql-quote-literal-example"/>.
3214 </para>
3215 <para>
3216 <literal>quote_literal(E'O\'Reilly')</literal>
3217 <returnvalue>'O''Reilly'</returnvalue>
3218 </para></entry>
3219 </row>
3221 <row>
3222 <entry role="func_table_entry"><para role="func_signature">
3223 <function>quote_literal</function> ( <type>anyelement</type> )
3224 <returnvalue>text</returnvalue>
3225 </para>
3226 <para>
3227 Converts the given value to text and then quotes it as a literal.
3228 Embedded single-quotes and backslashes are properly doubled.
3229 </para>
3230 <para>
3231 <literal>quote_literal(42.5)</literal>
3232 <returnvalue>'42.5'</returnvalue>
3233 </para></entry>
3234 </row>
3236 <row>
3237 <entry role="func_table_entry"><para role="func_signature">
3238 <indexterm>
3239 <primary>quote_nullable</primary>
3240 </indexterm>
3241 <function>quote_nullable</function> ( <type>text</type> )
3242 <returnvalue>text</returnvalue>
3243 </para>
3244 <para>
3245 Returns the given string suitably quoted to be used as a string literal
3246 in an <acronym>SQL</acronym> statement string; or, if the argument
3247 is null, returns <literal>NULL</literal>.
3248 Embedded single-quotes and backslashes are properly doubled.
3249 See also <xref linkend="plpgsql-quote-literal-example"/>.
3250 </para>
3251 <para>
3252 <literal>quote_nullable(NULL)</literal>
3253 <returnvalue>NULL</returnvalue>
3254 </para></entry>
3255 </row>
3257 <row>
3258 <entry role="func_table_entry"><para role="func_signature">
3259 <function>quote_nullable</function> ( <type>anyelement</type> )
3260 <returnvalue>text</returnvalue>
3261 </para>
3262 <para>
3263 Converts the given value to text and then quotes it as a literal;
3264 or, if the argument is null, returns <literal>NULL</literal>.
3265 Embedded single-quotes and backslashes are properly doubled.
3266 </para>
3267 <para>
3268 <literal>quote_nullable(42.5)</literal>
3269 <returnvalue>'42.5'</returnvalue>
3270 </para></entry>
3271 </row>
3273 <row>
3274 <entry role="func_table_entry"><para role="func_signature">
3275 <indexterm>
3276 <primary>regexp_count</primary>
3277 </indexterm>
3278 <function>regexp_count</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3279 [, <parameter>start</parameter> <type>integer</type>
3280 [, <parameter>flags</parameter> <type>text</type> ] ] )
3281 <returnvalue>integer</returnvalue>
3282 </para>
3283 <para>
3284 Returns the number of times the POSIX regular
3285 expression <parameter>pattern</parameter> matches in
3286 the <parameter>string</parameter>; see
3287 <xref linkend="functions-posix-regexp"/>.
3288 </para>
3289 <para>
3290 <literal>regexp_count('123456789012', '\d\d\d', 2)</literal>
3291 <returnvalue>3</returnvalue>
3292 </para></entry>
3293 </row>
3295 <row>
3296 <entry role="func_table_entry"><para role="func_signature">
3297 <indexterm>
3298 <primary>regexp_instr</primary>
3299 </indexterm>
3300 <function>regexp_instr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3301 [, <parameter>start</parameter> <type>integer</type>
3302 [, <parameter>N</parameter> <type>integer</type>
3303 [, <parameter>endoption</parameter> <type>integer</type>
3304 [, <parameter>flags</parameter> <type>text</type>
3305 [, <parameter>subexpr</parameter> <type>integer</type> ] ] ] ] ] )
3306 <returnvalue>integer</returnvalue>
3307 </para>
3308 <para>
3309 Returns the position within <parameter>string</parameter> where
3310 the <parameter>N</parameter>'th match of the POSIX regular
3311 expression <parameter>pattern</parameter> occurs, or zero if there is
3312 no such match; see <xref linkend="functions-posix-regexp"/>.
3313 </para>
3314 <para>
3315 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i')</literal>
3316 <returnvalue>3</returnvalue>
3317 </para>
3318 <para>
3319 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i', 2)</literal>
3320 <returnvalue>5</returnvalue>
3321 </para></entry>
3322 </row>
3324 <row>
3325 <entry role="func_table_entry"><para role="func_signature">
3326 <indexterm>
3327 <primary>regexp_like</primary>
3328 </indexterm>
3329 <function>regexp_like</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3330 [, <parameter>flags</parameter> <type>text</type> ] )
3331 <returnvalue>boolean</returnvalue>
3332 </para>
3333 <para>
3334 Checks whether a match of the POSIX regular
3335 expression <parameter>pattern</parameter> occurs
3336 within <parameter>string</parameter>; see
3337 <xref linkend="functions-posix-regexp"/>.
3338 </para>
3339 <para>
3340 <literal>regexp_like('Hello World', 'world$', 'i')</literal>
3341 <returnvalue>t</returnvalue>
3342 </para></entry>
3343 </row>
3345 <row>
3346 <entry role="func_table_entry"><para role="func_signature">
3347 <indexterm>
3348 <primary>regexp_match</primary>
3349 </indexterm>
3350 <function>regexp_match</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3351 <returnvalue>text[]</returnvalue>
3352 </para>
3353 <para>
3354 Returns substrings within the first match of the POSIX regular
3355 expression <parameter>pattern</parameter> to
3356 the <parameter>string</parameter>; see
3357 <xref linkend="functions-posix-regexp"/>.
3358 </para>
3359 <para>
3360 <literal>regexp_match('foobarbequebaz', '(bar)(beque)')</literal>
3361 <returnvalue>{bar,beque}</returnvalue>
3362 </para></entry>
3363 </row>
3365 <row>
3366 <entry role="func_table_entry"><para role="func_signature">
3367 <indexterm>
3368 <primary>regexp_matches</primary>
3369 </indexterm>
3370 <function>regexp_matches</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3371 <returnvalue>setof text[]</returnvalue>
3372 </para>
3373 <para>
3374 Returns substrings within the first match of the POSIX regular
3375 expression <parameter>pattern</parameter> to
3376 the <parameter>string</parameter>, or substrings within all
3377 such matches if the <literal>g</literal> flag is used;
3378 see <xref linkend="functions-posix-regexp"/>.
3379 </para>
3380 <para>
3381 <literal>regexp_matches('foobarbequebaz', 'ba.', 'g')</literal>
3382 <returnvalue></returnvalue>
3383 <programlisting>
3384 {bar}
3385 {baz}
3386 </programlisting>
3387 </para></entry>
3388 </row>
3390 <row>
3391 <entry role="func_table_entry"><para role="func_signature">
3392 <indexterm>
3393 <primary>regexp_replace</primary>
3394 </indexterm>
3395 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>
3396 [, <parameter>start</parameter> <type>integer</type> ]
3397 [, <parameter>flags</parameter> <type>text</type> ] )
3398 <returnvalue>text</returnvalue>
3399 </para>
3400 <para>
3401 Replaces the substring that is the first match to the POSIX
3402 regular expression <parameter>pattern</parameter>, or all such
3403 matches if the <literal>g</literal> flag is used; see
3404 <xref linkend="functions-posix-regexp"/>.
3405 </para>
3406 <para>
3407 <literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal>
3408 <returnvalue>ThM</returnvalue>
3409 </para></entry>
3410 </row>
3412 <row>
3413 <entry role="func_table_entry"><para role="func_signature">
3414 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>,
3415 <parameter>start</parameter> <type>integer</type>,
3416 <parameter>N</parameter> <type>integer</type>
3417 [, <parameter>flags</parameter> <type>text</type> ] )
3418 <returnvalue>text</returnvalue>
3419 </para>
3420 <para>
3421 Replaces the substring that is the <parameter>N</parameter>'th
3422 match to the POSIX regular expression <parameter>pattern</parameter>,
3423 or all such matches if <parameter>N</parameter> is zero; see
3424 <xref linkend="functions-posix-regexp"/>.
3425 </para>
3426 <para>
3427 <literal>regexp_replace('Thomas', '.', 'X', 3, 2)</literal>
3428 <returnvalue>ThoXas</returnvalue>
3429 </para></entry>
3430 </row>
3432 <row>
3433 <entry role="func_table_entry"><para role="func_signature">
3434 <indexterm>
3435 <primary>regexp_split_to_array</primary>
3436 </indexterm>
3437 <function>regexp_split_to_array</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3438 <returnvalue>text[]</returnvalue>
3439 </para>
3440 <para>
3441 Splits <parameter>string</parameter> using a POSIX regular
3442 expression as the delimiter, producing an array of results; see
3443 <xref linkend="functions-posix-regexp"/>.
3444 </para>
3445 <para>
3446 <literal>regexp_split_to_array('hello world', '\s+')</literal>
3447 <returnvalue>{hello,world}</returnvalue>
3448 </para></entry>
3449 </row>
3451 <row>
3452 <entry role="func_table_entry"><para role="func_signature">
3453 <indexterm>
3454 <primary>regexp_split_to_table</primary>
3455 </indexterm>
3456 <function>regexp_split_to_table</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3457 <returnvalue>setof text</returnvalue>
3458 </para>
3459 <para>
3460 Splits <parameter>string</parameter> using a POSIX regular
3461 expression as the delimiter, producing a set of results; see
3462 <xref linkend="functions-posix-regexp"/>.
3463 </para>
3464 <para>
3465 <literal>regexp_split_to_table('hello world', '\s+')</literal>
3466 <returnvalue></returnvalue>
3467 <programlisting>
3468 hello
3469 world
3470 </programlisting>
3471 </para></entry>
3472 </row>
3474 <row>
3475 <entry role="func_table_entry"><para role="func_signature">
3476 <indexterm>
3477 <primary>regexp_substr</primary>
3478 </indexterm>
3479 <function>regexp_substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3480 [, <parameter>start</parameter> <type>integer</type>
3481 [, <parameter>N</parameter> <type>integer</type>
3482 [, <parameter>flags</parameter> <type>text</type>
3483 [, <parameter>subexpr</parameter> <type>integer</type> ] ] ] ] )
3484 <returnvalue>text</returnvalue>
3485 </para>
3486 <para>
3487 Returns the substring within <parameter>string</parameter> that
3488 matches the <parameter>N</parameter>'th occurrence of the POSIX
3489 regular expression <parameter>pattern</parameter>,
3490 or <literal>NULL</literal> if there is no such match; see
3491 <xref linkend="functions-posix-regexp"/>.
3492 </para>
3493 <para>
3494 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i')</literal>
3495 <returnvalue>CDEF</returnvalue>
3496 </para>
3497 <para>
3498 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i', 2)</literal>
3499 <returnvalue>EF</returnvalue>
3500 </para></entry>
3501 </row>
3503 <row>
3504 <entry role="func_table_entry"><para role="func_signature">
3505 <indexterm>
3506 <primary>repeat</primary>
3507 </indexterm>
3508 <function>repeat</function> ( <parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>integer</type> )
3509 <returnvalue>text</returnvalue>
3510 </para>
3511 <para>
3512 Repeats <parameter>string</parameter> the specified
3513 <parameter>number</parameter> of times.
3514 </para>
3515 <para>
3516 <literal>repeat('Pg', 4)</literal>
3517 <returnvalue>PgPgPgPg</returnvalue>
3518 </para></entry>
3519 </row>
3521 <row>
3522 <entry role="func_table_entry"><para role="func_signature">
3523 <indexterm>
3524 <primary>replace</primary>
3525 </indexterm>
3526 <function>replace</function> ( <parameter>string</parameter> <type>text</type>,
3527 <parameter>from</parameter> <type>text</type>,
3528 <parameter>to</parameter> <type>text</type> )
3529 <returnvalue>text</returnvalue>
3530 </para>
3531 <para>
3532 Replaces all occurrences in <parameter>string</parameter> of
3533 substring <parameter>from</parameter> with
3534 substring <parameter>to</parameter>.
3535 </para>
3536 <para>
3537 <literal>replace('abcdefabcdef', 'cd', 'XX')</literal>
3538 <returnvalue>abXXefabXXef</returnvalue>
3539 </para></entry>
3540 </row>
3542 <row>
3543 <entry role="func_table_entry"><para role="func_signature">
3544 <indexterm>
3545 <primary>reverse</primary>
3546 </indexterm>
3547 <function>reverse</function> ( <type>text</type> )
3548 <returnvalue>text</returnvalue>
3549 </para>
3550 <para>
3551 Reverses the order of the characters in the string.
3552 </para>
3553 <para>
3554 <literal>reverse('abcde')</literal>
3555 <returnvalue>edcba</returnvalue>
3556 </para></entry>
3557 </row>
3559 <row>
3560 <entry role="func_table_entry"><para role="func_signature">
3561 <indexterm>
3562 <primary>right</primary>
3563 </indexterm>
3564 <function>right</function> ( <parameter>string</parameter> <type>text</type>,
3565 <parameter>n</parameter> <type>integer</type> )
3566 <returnvalue>text</returnvalue>
3567 </para>
3568 <para>
3569 Returns last <parameter>n</parameter> characters in the string,
3570 or when <parameter>n</parameter> is negative, returns all but
3571 first |<parameter>n</parameter>| characters.
3572 </para>
3573 <para>
3574 <literal>right('abcde', 2)</literal>
3575 <returnvalue>de</returnvalue>
3576 </para></entry>
3577 </row>
3579 <row>
3580 <entry role="func_table_entry"><para role="func_signature">
3581 <indexterm>
3582 <primary>split_part</primary>
3583 </indexterm>
3584 <function>split_part</function> ( <parameter>string</parameter> <type>text</type>,
3585 <parameter>delimiter</parameter> <type>text</type>,
3586 <parameter>n</parameter> <type>integer</type> )
3587 <returnvalue>text</returnvalue>
3588 </para>
3589 <para>
3590 Splits <parameter>string</parameter> at occurrences
3591 of <parameter>delimiter</parameter> and returns
3592 the <parameter>n</parameter>'th field (counting from one),
3593 or when <parameter>n</parameter> is negative, returns
3594 the |<parameter>n</parameter>|'th-from-last field.
3595 </para>
3596 <para>
3597 <literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal>
3598 <returnvalue>def</returnvalue>
3599 </para>
3600 <para>
3601 <literal>split_part('abc,def,ghi,jkl', ',', -2)</literal>
3602 <returnvalue>ghi</returnvalue>
3603 </para></entry>
3604 </row>
3606 <row>
3607 <entry role="func_table_entry"><para role="func_signature">
3608 <indexterm>
3609 <primary>starts_with</primary>
3610 </indexterm>
3611 <function>starts_with</function> ( <parameter>string</parameter> <type>text</type>, <parameter>prefix</parameter> <type>text</type> )
3612 <returnvalue>boolean</returnvalue>
3613 </para>
3614 <para>
3615 Returns true if <parameter>string</parameter> starts
3616 with <parameter>prefix</parameter>.
3617 </para>
3618 <para>
3619 <literal>starts_with('alphabet', 'alph')</literal>
3620 <returnvalue>t</returnvalue>
3621 </para></entry>
3622 </row>
3624 <row>
3625 <entry role="func_table_entry"><para role="func_signature">
3626 <indexterm id="function-string-to-array">
3627 <primary>string_to_array</primary>
3628 </indexterm>
3629 <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> )
3630 <returnvalue>text[]</returnvalue>
3631 </para>
3632 <para>
3633 Splits the <parameter>string</parameter> at occurrences
3634 of <parameter>delimiter</parameter> and forms the resulting fields
3635 into a <type>text</type> array.
3636 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3637 each character in the <parameter>string</parameter> will become a
3638 separate element in the array.
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 See also <link linkend="function-array-to-string"><function>array_to_string</function></link>.
3645 </para>
3646 <para>
3647 <literal>string_to_array('xx~~yy~~zz', '~~', 'yy')</literal>
3648 <returnvalue>{xx,NULL,zz}</returnvalue>
3649 </para></entry>
3650 </row>
3652 <row>
3653 <entry role="func_table_entry"><para role="func_signature">
3654 <indexterm>
3655 <primary>string_to_table</primary>
3656 </indexterm>
3657 <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> )
3658 <returnvalue>setof text</returnvalue>
3659 </para>
3660 <para>
3661 Splits the <parameter>string</parameter> at occurrences
3662 of <parameter>delimiter</parameter> and returns the resulting fields
3663 as a set of <type>text</type> rows.
3664 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3665 each character in the <parameter>string</parameter> will become a
3666 separate row of the result.
3667 If <parameter>delimiter</parameter> is an empty string, then
3668 the <parameter>string</parameter> is treated as a single field.
3669 If <parameter>null_string</parameter> is supplied and is
3670 not <literal>NULL</literal>, fields matching that string are
3671 replaced by <literal>NULL</literal>.
3672 </para>
3673 <para>
3674 <literal>string_to_table('xx~^~yy~^~zz', '~^~', 'yy')</literal>
3675 <returnvalue></returnvalue>
3676 <programlisting>
3678 NULL
3680 </programlisting>
3681 </para></entry>
3682 </row>
3684 <row>
3685 <entry role="func_table_entry"><para role="func_signature">
3686 <indexterm>
3687 <primary>strpos</primary>
3688 </indexterm>
3689 <function>strpos</function> ( <parameter>string</parameter> <type>text</type>, <parameter>substring</parameter> <type>text</type> )
3690 <returnvalue>integer</returnvalue>
3691 </para>
3692 <para>
3693 Returns first starting index of the specified <parameter>substring</parameter>
3694 within <parameter>string</parameter>, or zero if it's not present.
3695 (Same as <literal>position(<parameter>substring</parameter> in
3696 <parameter>string</parameter>)</literal>, but note the reversed
3697 argument order.)
3698 </para>
3699 <para>
3700 <literal>strpos('high', 'ig')</literal>
3701 <returnvalue>2</returnvalue>
3702 </para></entry>
3703 </row>
3705 <row>
3706 <entry role="func_table_entry"><para role="func_signature">
3707 <indexterm>
3708 <primary>substr</primary>
3709 </indexterm>
3710 <function>substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
3711 <returnvalue>text</returnvalue>
3712 </para>
3713 <para>
3714 Extracts the substring of <parameter>string</parameter> starting at
3715 the <parameter>start</parameter>'th character,
3716 and extending for <parameter>count</parameter> characters if that is
3717 specified. (Same
3718 as <literal>substring(<parameter>string</parameter>
3719 from <parameter>start</parameter>
3720 for <parameter>count</parameter>)</literal>.)
3721 </para>
3722 <para>
3723 <literal>substr('alphabet', 3)</literal>
3724 <returnvalue>phabet</returnvalue>
3725 </para>
3726 <para>
3727 <literal>substr('alphabet', 3, 2)</literal>
3728 <returnvalue>ph</returnvalue>
3729 </para></entry>
3730 </row>
3732 <row>
3733 <entry role="func_table_entry"><para role="func_signature">
3734 <indexterm>
3735 <primary>to_ascii</primary>
3736 </indexterm>
3737 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type> )
3738 <returnvalue>text</returnvalue>
3739 </para>
3740 <para role="func_signature">
3741 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3742 <parameter>encoding</parameter> <type>name</type> )
3743 <returnvalue>text</returnvalue>
3744 </para>
3745 <para role="func_signature">
3746 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3747 <parameter>encoding</parameter> <type>integer</type> )
3748 <returnvalue>text</returnvalue>
3749 </para>
3750 <para>
3751 Converts <parameter>string</parameter> to <acronym>ASCII</acronym>
3752 from another encoding, which may be identified by name or number.
3753 If <parameter>encoding</parameter> is omitted the database encoding
3754 is assumed (which in practice is the only useful case).
3755 The conversion consists primarily of dropping accents.
3756 Conversion is only supported
3757 from <literal>LATIN1</literal>, <literal>LATIN2</literal>,
3758 <literal>LATIN9</literal>, and <literal>WIN1250</literal> encodings.
3759 (See the <xref linkend="unaccent"/> module for another, more flexible
3760 solution.)
3761 </para>
3762 <para>
3763 <literal>to_ascii('Kar&eacute;l')</literal>
3764 <returnvalue>Karel</returnvalue>
3765 </para></entry>
3766 </row>
3768 <row>
3769 <entry role="func_table_entry"><para role="func_signature">
3770 <indexterm>
3771 <primary>to_bin</primary>
3772 </indexterm>
3773 <function>to_bin</function> ( <type>integer</type> )
3774 <returnvalue>text</returnvalue>
3775 </para>
3776 <para role="func_signature">
3777 <function>to_bin</function> ( <type>bigint</type> )
3778 <returnvalue>text</returnvalue>
3779 </para>
3780 <para>
3781 Converts the number to its equivalent two's complement binary
3782 representation.
3783 </para>
3784 <para>
3785 <literal>to_bin(2147483647)</literal>
3786 <returnvalue>1111111111111111111111111111111</returnvalue>
3787 </para>
3788 <para>
3789 <literal>to_bin(-1234)</literal>
3790 <returnvalue>11111111111111111111101100101110</returnvalue>
3791 </para></entry>
3792 </row>
3794 <row>
3795 <entry role="func_table_entry"><para role="func_signature">
3796 <indexterm>
3797 <primary>to_hex</primary>
3798 </indexterm>
3799 <function>to_hex</function> ( <type>integer</type> )
3800 <returnvalue>text</returnvalue>
3801 </para>
3802 <para role="func_signature">
3803 <function>to_hex</function> ( <type>bigint</type> )
3804 <returnvalue>text</returnvalue>
3805 </para>
3806 <para>
3807 Converts the number to its equivalent two's complement hexadecimal
3808 representation.
3809 </para>
3810 <para>
3811 <literal>to_hex(2147483647)</literal>
3812 <returnvalue>7fffffff</returnvalue>
3813 </para>
3814 <para>
3815 <literal>to_hex(-1234)</literal>
3816 <returnvalue>fffffb2e</returnvalue>
3817 </para></entry>
3818 </row>
3820 <row>
3821 <entry role="func_table_entry"><para role="func_signature">
3822 <indexterm>
3823 <primary>to_oct</primary>
3824 </indexterm>
3825 <function>to_oct</function> ( <type>integer</type> )
3826 <returnvalue>text</returnvalue>
3827 </para>
3828 <para role="func_signature">
3829 <function>to_oct</function> ( <type>bigint</type> )
3830 <returnvalue>text</returnvalue>
3831 </para>
3832 <para>
3833 Converts the number to its equivalent two's complement octal
3834 representation.
3835 </para>
3836 <para>
3837 <literal>to_oct(2147483647)</literal>
3838 <returnvalue>17777777777</returnvalue>
3839 </para>
3840 <para>
3841 <literal>to_oct(-1234)</literal>
3842 <returnvalue>37777775456</returnvalue>
3843 </para></entry>
3844 </row>
3846 <row>
3847 <entry role="func_table_entry"><para role="func_signature">
3848 <indexterm>
3849 <primary>translate</primary>
3850 </indexterm>
3851 <function>translate</function> ( <parameter>string</parameter> <type>text</type>,
3852 <parameter>from</parameter> <type>text</type>,
3853 <parameter>to</parameter> <type>text</type> )
3854 <returnvalue>text</returnvalue>
3855 </para>
3856 <para>
3857 Replaces each character in <parameter>string</parameter> that
3858 matches a character in the <parameter>from</parameter> set with the
3859 corresponding character in the <parameter>to</parameter>
3860 set. If <parameter>from</parameter> is longer than
3861 <parameter>to</parameter>, occurrences of the extra characters in
3862 <parameter>from</parameter> are deleted.
3863 </para>
3864 <para>
3865 <literal>translate('12345', '143', 'ax')</literal>
3866 <returnvalue>a2x5</returnvalue>
3867 </para></entry>
3868 </row>
3870 <row>
3871 <entry role="func_table_entry"><para role="func_signature">
3872 <indexterm>
3873 <primary>unistr</primary>
3874 </indexterm>
3875 <function>unistr</function> ( <type>text</type> )
3876 <returnvalue>text</returnvalue>
3877 </para>
3878 <para>
3879 Evaluate escaped Unicode characters in the argument. Unicode characters
3880 can be specified as
3881 <literal>\<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3882 digits), <literal>\+<replaceable>XXXXXX</replaceable></literal> (6
3883 hexadecimal digits),
3884 <literal>\u<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3885 digits), or <literal>\U<replaceable>XXXXXXXX</replaceable></literal>
3886 (8 hexadecimal digits). To specify a backslash, write two
3887 backslashes. All other characters are taken literally.
3888 </para>
3890 <para>
3891 If the server encoding is not UTF-8, the Unicode code point identified
3892 by one of these escape sequences is converted to the actual server
3893 encoding; an error is reported if that's not possible.
3894 </para>
3896 <para>
3897 This function provides a (non-standard) alternative to string
3898 constants with Unicode escapes (see <xref
3899 linkend="sql-syntax-strings-uescape"/>).
3900 </para>
3902 <para>
3903 <literal>unistr('d\0061t\+000061')</literal>
3904 <returnvalue>data</returnvalue>
3905 </para>
3906 <para>
3907 <literal>unistr('d\u0061t\U00000061')</literal>
3908 <returnvalue>data</returnvalue>
3909 </para></entry>
3910 </row>
3912 </tbody>
3913 </tgroup>
3914 </table>
3916 <para>
3917 The <function>concat</function>, <function>concat_ws</function> and
3918 <function>format</function> functions are variadic, so it is possible to
3919 pass the values to be concatenated or formatted as an array marked with
3920 the <literal>VARIADIC</literal> keyword (see <xref
3921 linkend="xfunc-sql-variadic-functions"/>). The array's elements are
3922 treated as if they were separate ordinary arguments to the function.
3923 If the variadic array argument is NULL, <function>concat</function>
3924 and <function>concat_ws</function> return NULL, but
3925 <function>format</function> treats a NULL as a zero-element array.
3926 </para>
3928 <para>
3929 See also the aggregate function <function>string_agg</function> in
3930 <xref linkend="functions-aggregate"/>, and the functions for
3931 converting between strings and the <type>bytea</type> type in
3932 <xref linkend="functions-binarystring-conversions"/>.
3933 </para>
3935 <sect2 id="functions-string-format">
3936 <title><function>format</function></title>
3938 <indexterm>
3939 <primary>format</primary>
3940 </indexterm>
3942 <para>
3943 The function <function>format</function> produces output formatted according to
3944 a format string, in a style similar to the C function
3945 <function>sprintf</function>.
3946 </para>
3948 <para>
3949 <synopsis>
3950 <function>format</function>(<parameter>formatstr</parameter> <type>text</type> [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])
3951 </synopsis>
3952 <parameter>formatstr</parameter> is a format string that specifies how the
3953 result should be formatted. Text in the format string is copied
3954 directly to the result, except where <firstterm>format specifiers</firstterm> are
3955 used. Format specifiers act as placeholders in the string, defining how
3956 subsequent function arguments should be formatted and inserted into the
3957 result. Each <parameter>formatarg</parameter> argument is converted to text
3958 according to the usual output rules for its data type, and then formatted
3959 and inserted into the result string according to the format specifier(s).
3960 </para>
3962 <para>
3963 Format specifiers are introduced by a <literal>%</literal> character and have
3964 the form
3965 <synopsis>
3966 %[<parameter>position</parameter>][<parameter>flags</parameter>][<parameter>width</parameter>]<parameter>type</parameter>
3967 </synopsis>
3968 where the component fields are:
3970 <variablelist>
3971 <varlistentry>
3972 <term><parameter>position</parameter> (optional)</term>
3973 <listitem>
3974 <para>
3975 A string of the form <literal><parameter>n</parameter>$</literal> where
3976 <parameter>n</parameter> is the index of the argument to print.
3977 Index 1 means the first argument after
3978 <parameter>formatstr</parameter>. If the <parameter>position</parameter> is
3979 omitted, the default is to use the next argument in sequence.
3980 </para>
3981 </listitem>
3982 </varlistentry>
3984 <varlistentry>
3985 <term><parameter>flags</parameter> (optional)</term>
3986 <listitem>
3987 <para>
3988 Additional options controlling how the format specifier's output is
3989 formatted. Currently the only supported flag is a minus sign
3990 (<literal>-</literal>) which will cause the format specifier's output to be
3991 left-justified. This has no effect unless the <parameter>width</parameter>
3992 field is also specified.
3993 </para>
3994 </listitem>
3995 </varlistentry>
3997 <varlistentry>
3998 <term><parameter>width</parameter> (optional)</term>
3999 <listitem>
4000 <para>
4001 Specifies the <emphasis>minimum</emphasis> number of characters to use to
4002 display the format specifier's output. The output is padded on the
4003 left or right (depending on the <literal>-</literal> flag) with spaces as
4004 needed to fill the width. A too-small width does not cause
4005 truncation of the output, but is simply ignored. The width may be
4006 specified using any of the following: a positive integer; an
4007 asterisk (<literal>*</literal>) to use the next function argument as the
4008 width; or a string of the form <literal>*<parameter>n</parameter>$</literal> to
4009 use the <parameter>n</parameter>th function argument as the width.
4010 </para>
4012 <para>
4013 If the width comes from a function argument, that argument is
4014 consumed before the argument that is used for the format specifier's
4015 value. If the width argument is negative, the result is left
4016 aligned (as if the <literal>-</literal> flag had been specified) within a
4017 field of length <function>abs</function>(<parameter>width</parameter>).
4018 </para>
4019 </listitem>
4020 </varlistentry>
4022 <varlistentry>
4023 <term><parameter>type</parameter> (required)</term>
4024 <listitem>
4025 <para>
4026 The type of format conversion to use to produce the format
4027 specifier's output. The following types are supported:
4028 <itemizedlist>
4029 <listitem>
4030 <para>
4031 <literal>s</literal> formats the argument value as a simple
4032 string. A null value is treated as an empty string.
4033 </para>
4034 </listitem>
4035 <listitem>
4036 <para>
4037 <literal>I</literal> treats the argument value as an SQL
4038 identifier, double-quoting it if necessary.
4039 It is an error for the value to be null (equivalent to
4040 <function>quote_ident</function>).
4041 </para>
4042 </listitem>
4043 <listitem>
4044 <para>
4045 <literal>L</literal> quotes the argument value as an SQL literal.
4046 A null value is displayed as the string <literal>NULL</literal>, without
4047 quotes (equivalent to <function>quote_nullable</function>).
4048 </para>
4049 </listitem>
4050 </itemizedlist>
4051 </para>
4052 </listitem>
4053 </varlistentry>
4054 </variablelist>
4055 </para>
4057 <para>
4058 In addition to the format specifiers described above, the special sequence
4059 <literal>%%</literal> may be used to output a literal <literal>%</literal> character.
4060 </para>
4062 <para>
4063 Here are some examples of the basic format conversions:
4065 <screen>
4066 SELECT format('Hello %s', 'World');
4067 <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
4069 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
4070 <lineannotation>Result: </lineannotation><computeroutput>Testing one, two, three, %</computeroutput>
4072 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
4073 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
4075 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
4076 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')</computeroutput>
4077 </screen>
4078 </para>
4080 <para>
4081 Here are examples using <parameter>width</parameter> fields
4082 and the <literal>-</literal> flag:
4084 <screen>
4085 SELECT format('|%10s|', 'foo');
4086 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4088 SELECT format('|%-10s|', 'foo');
4089 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4091 SELECT format('|%*s|', 10, 'foo');
4092 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4094 SELECT format('|%*s|', -10, 'foo');
4095 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4097 SELECT format('|%-*s|', 10, 'foo');
4098 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4100 SELECT format('|%-*s|', -10, 'foo');
4101 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4102 </screen>
4103 </para>
4105 <para>
4106 These examples show use of <parameter>position</parameter> fields:
4108 <screen>
4109 SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
4110 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, one</computeroutput>
4112 SELECT format('|%*2$s|', 'foo', 10, 'bar');
4113 <lineannotation>Result: </lineannotation><computeroutput>| bar|</computeroutput>
4115 SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
4116 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4117 </screen>
4118 </para>
4120 <para>
4121 Unlike the standard C function <function>sprintf</function>,
4122 <productname>PostgreSQL</productname>'s <function>format</function> function allows format
4123 specifiers with and without <parameter>position</parameter> fields to be mixed
4124 in the same format string. A format specifier without a
4125 <parameter>position</parameter> field always uses the next argument after the
4126 last argument consumed.
4127 In addition, the <function>format</function> function does not require all
4128 function arguments to be used in the format string.
4129 For example:
4131 <screen>
4132 SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
4133 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, three</computeroutput>
4134 </screen>
4135 </para>
4137 <para>
4138 The <literal>%I</literal> and <literal>%L</literal> format specifiers are particularly
4139 useful for safely constructing dynamic SQL statements. See
4140 <xref linkend="plpgsql-quote-literal-example"/>.
4141 </para>
4142 </sect2>
4144 </sect1>
4147 <sect1 id="functions-binarystring">
4148 <title>Binary String Functions and Operators</title>
4150 <indexterm zone="functions-binarystring">
4151 <primary>binary data</primary>
4152 <secondary>functions</secondary>
4153 </indexterm>
4155 <para>
4156 This section describes functions and operators for examining and
4157 manipulating binary strings, that is values of type <type>bytea</type>.
4158 Many of these are equivalent, in purpose and syntax, to the
4159 text-string functions described in the previous section.
4160 </para>
4162 <para>
4163 <acronym>SQL</acronym> defines some string functions that use
4164 key words, rather than commas, to separate
4165 arguments. Details are in
4166 <xref linkend="functions-binarystring-sql"/>.
4167 <productname>PostgreSQL</productname> also provides versions of these functions
4168 that use the regular function invocation syntax
4169 (see <xref linkend="functions-binarystring-other"/>).
4170 </para>
4172 <table id="functions-binarystring-sql">
4173 <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
4174 <tgroup cols="1">
4175 <thead>
4176 <row>
4177 <entry role="func_table_entry"><para role="func_signature">
4178 Function/Operator
4179 </para>
4180 <para>
4181 Description
4182 </para>
4183 <para>
4184 Example(s)
4185 </para></entry>
4186 </row>
4187 </thead>
4189 <tbody>
4190 <row>
4191 <entry role="func_table_entry"><para role="func_signature">
4192 <indexterm>
4193 <primary>binary string</primary>
4194 <secondary>concatenation</secondary>
4195 </indexterm>
4196 <type>bytea</type> <literal>||</literal> <type>bytea</type>
4197 <returnvalue>bytea</returnvalue>
4198 </para>
4199 <para>
4200 Concatenates the two binary strings.
4201 </para>
4202 <para>
4203 <literal>'\x123456'::bytea || '\x789a00bcde'::bytea</literal>
4204 <returnvalue>\x123456789a00bcde</returnvalue>
4205 </para></entry>
4206 </row>
4208 <row>
4209 <entry role="func_table_entry"><para role="func_signature">
4210 <indexterm>
4211 <primary>bit_length</primary>
4212 </indexterm>
4213 <function>bit_length</function> ( <type>bytea</type> )
4214 <returnvalue>integer</returnvalue>
4215 </para>
4216 <para>
4217 Returns number of bits in the binary string (8
4218 times the <function>octet_length</function>).
4219 </para>
4220 <para>
4221 <literal>bit_length('\x123456'::bytea)</literal>
4222 <returnvalue>24</returnvalue>
4223 </para></entry>
4224 </row>
4226 <row>
4227 <entry role="func_table_entry"><para role="func_signature">
4228 <indexterm>
4229 <primary>btrim</primary>
4230 </indexterm>
4231 <function>btrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4232 <parameter>bytesremoved</parameter> <type>bytea</type> )
4233 <returnvalue>bytea</returnvalue>
4234 </para>
4235 <para>
4236 Removes the longest string containing only bytes appearing in
4237 <parameter>bytesremoved</parameter> from the start and end of
4238 <parameter>bytes</parameter>.
4239 </para>
4240 <para>
4241 <literal>btrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4242 <returnvalue>\x345678</returnvalue>
4243 </para></entry>
4244 </row>
4246 <row>
4247 <entry role="func_table_entry"><para role="func_signature">
4248 <indexterm>
4249 <primary>ltrim</primary>
4250 </indexterm>
4251 <function>ltrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4252 <parameter>bytesremoved</parameter> <type>bytea</type> )
4253 <returnvalue>bytea</returnvalue>
4254 </para>
4255 <para>
4256 Removes the longest string containing only bytes appearing in
4257 <parameter>bytesremoved</parameter> from the start of
4258 <parameter>bytes</parameter>.
4259 </para>
4260 <para>
4261 <literal>ltrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4262 <returnvalue>\x34567890</returnvalue>
4263 </para></entry>
4264 </row>
4266 <row>
4267 <entry role="func_table_entry"><para role="func_signature">
4268 <indexterm>
4269 <primary>octet_length</primary>
4270 </indexterm>
4271 <function>octet_length</function> ( <type>bytea</type> )
4272 <returnvalue>integer</returnvalue>
4273 </para>
4274 <para>
4275 Returns number of bytes in the binary string.
4276 </para>
4277 <para>
4278 <literal>octet_length('\x123456'::bytea)</literal>
4279 <returnvalue>3</returnvalue>
4280 </para></entry>
4281 </row>
4283 <row>
4284 <entry role="func_table_entry"><para role="func_signature">
4285 <indexterm>
4286 <primary>overlay</primary>
4287 </indexterm>
4288 <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> )
4289 <returnvalue>bytea</returnvalue>
4290 </para>
4291 <para>
4292 Replaces the substring of <parameter>bytes</parameter> that starts at
4293 the <parameter>start</parameter>'th byte and extends
4294 for <parameter>count</parameter> bytes
4295 with <parameter>newsubstring</parameter>.
4296 If <parameter>count</parameter> is omitted, it defaults to the length
4297 of <parameter>newsubstring</parameter>.
4298 </para>
4299 <para>
4300 <literal>overlay('\x1234567890'::bytea placing '\002\003'::bytea from 2 for 3)</literal>
4301 <returnvalue>\x12020390</returnvalue>
4302 </para></entry>
4303 </row>
4305 <row>
4306 <entry role="func_table_entry"><para role="func_signature">
4307 <indexterm>
4308 <primary>position</primary>
4309 </indexterm>
4310 <function>position</function> ( <parameter>substring</parameter> <type>bytea</type> <literal>IN</literal> <parameter>bytes</parameter> <type>bytea</type> )
4311 <returnvalue>integer</returnvalue>
4312 </para>
4313 <para>
4314 Returns first starting index of the specified
4315 <parameter>substring</parameter> within
4316 <parameter>bytes</parameter>, or zero if it's not present.
4317 </para>
4318 <para>
4319 <literal>position('\x5678'::bytea in '\x1234567890'::bytea)</literal>
4320 <returnvalue>3</returnvalue>
4321 </para></entry>
4322 </row>
4324 <row>
4325 <entry role="func_table_entry"><para role="func_signature">
4326 <indexterm>
4327 <primary>rtrim</primary>
4328 </indexterm>
4329 <function>rtrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4330 <parameter>bytesremoved</parameter> <type>bytea</type> )
4331 <returnvalue>bytea</returnvalue>
4332 </para>
4333 <para>
4334 Removes the longest string containing only bytes appearing in
4335 <parameter>bytesremoved</parameter> from the end of
4336 <parameter>bytes</parameter>.
4337 </para>
4338 <para>
4339 <literal>rtrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4340 <returnvalue>\x12345678</returnvalue>
4341 </para></entry>
4342 </row>
4344 <row>
4345 <entry role="func_table_entry"><para role="func_signature">
4346 <indexterm>
4347 <primary>substring</primary>
4348 </indexterm>
4349 <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> )
4350 <returnvalue>bytea</returnvalue>
4351 </para>
4352 <para>
4353 Extracts the substring of <parameter>bytes</parameter> starting at
4354 the <parameter>start</parameter>'th byte if that is specified,
4355 and stopping after <parameter>count</parameter> bytes if that is
4356 specified. Provide at least one of <parameter>start</parameter>
4357 and <parameter>count</parameter>.
4358 </para>
4359 <para>
4360 <literal>substring('\x1234567890'::bytea from 3 for 2)</literal>
4361 <returnvalue>\x5678</returnvalue>
4362 </para></entry>
4363 </row>
4365 <row>
4366 <entry role="func_table_entry"><para role="func_signature">
4367 <indexterm>
4368 <primary>trim</primary>
4369 </indexterm>
4370 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
4371 <parameter>bytesremoved</parameter> <type>bytea</type> <literal>FROM</literal>
4372 <parameter>bytes</parameter> <type>bytea</type> )
4373 <returnvalue>bytea</returnvalue>
4374 </para>
4375 <para>
4376 Removes the longest string containing only bytes appearing in
4377 <parameter>bytesremoved</parameter> from the start,
4378 end, or both ends (<literal>BOTH</literal> is the default)
4379 of <parameter>bytes</parameter>.
4380 </para>
4381 <para>
4382 <literal>trim('\x9012'::bytea from '\x1234567890'::bytea)</literal>
4383 <returnvalue>\x345678</returnvalue>
4384 </para></entry>
4385 </row>
4387 <row>
4388 <entry role="func_table_entry"><para role="func_signature">
4389 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
4390 <parameter>bytes</parameter> <type>bytea</type>,
4391 <parameter>bytesremoved</parameter> <type>bytea</type> )
4392 <returnvalue>bytea</returnvalue>
4393 </para>
4394 <para>
4395 This is a non-standard syntax for <function>trim()</function>.
4396 </para>
4397 <para>
4398 <literal>trim(both from '\x1234567890'::bytea, '\x9012'::bytea)</literal>
4399 <returnvalue>\x345678</returnvalue>
4400 </para></entry>
4401 </row>
4402 </tbody>
4403 </tgroup>
4404 </table>
4406 <para>
4407 Additional binary string manipulation functions are available and
4408 are listed in <xref linkend="functions-binarystring-other"/>. Some
4409 of them are used internally to implement the
4410 <acronym>SQL</acronym>-standard string functions listed in <xref
4411 linkend="functions-binarystring-sql"/>.
4412 </para>
4414 <table id="functions-binarystring-other">
4415 <title>Other Binary String Functions</title>
4416 <tgroup cols="1">
4417 <thead>
4418 <row>
4419 <entry role="func_table_entry"><para role="func_signature">
4420 Function
4421 </para>
4422 <para>
4423 Description
4424 </para>
4425 <para>
4426 Example(s)
4427 </para></entry>
4428 </row>
4429 </thead>
4431 <tbody>
4432 <row>
4433 <entry role="func_table_entry"><para role="func_signature">
4434 <indexterm>
4435 <primary>bit_count</primary>
4436 </indexterm>
4437 <indexterm>
4438 <primary>popcount</primary>
4439 <see>bit_count</see>
4440 </indexterm>
4441 <function>bit_count</function> ( <parameter>bytes</parameter> <type>bytea</type> )
4442 <returnvalue>bigint</returnvalue>
4443 </para>
4444 <para>
4445 Returns the number of bits set in the binary string (also known as
4446 <quote>popcount</quote>).
4447 </para>
4448 <para>
4449 <literal>bit_count('\x1234567890'::bytea)</literal>
4450 <returnvalue>15</returnvalue>
4451 </para></entry>
4452 </row>
4454 <row>
4455 <entry role="func_table_entry"><para role="func_signature">
4456 <indexterm>
4457 <primary>get_bit</primary>
4458 </indexterm>
4459 <function>get_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4460 <parameter>n</parameter> <type>bigint</type> )
4461 <returnvalue>integer</returnvalue>
4462 </para>
4463 <para>
4464 Extracts <link linkend="functions-zerobased-note">n'th</link> bit
4465 from binary string.
4466 </para>
4467 <para>
4468 <literal>get_bit('\x1234567890'::bytea, 30)</literal>
4469 <returnvalue>1</returnvalue>
4470 </para></entry>
4471 </row>
4473 <row>
4474 <entry role="func_table_entry"><para role="func_signature">
4475 <indexterm>
4476 <primary>get_byte</primary>
4477 </indexterm>
4478 <function>get_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4479 <parameter>n</parameter> <type>integer</type> )
4480 <returnvalue>integer</returnvalue>
4481 </para>
4482 <para>
4483 Extracts <link linkend="functions-zerobased-note">n'th</link> byte
4484 from binary string.
4485 </para>
4486 <para>
4487 <literal>get_byte('\x1234567890'::bytea, 4)</literal>
4488 <returnvalue>144</returnvalue>
4489 </para></entry>
4490 </row>
4492 <row>
4493 <entry role="func_table_entry"><para role="func_signature">
4494 <indexterm>
4495 <primary>length</primary>
4496 </indexterm>
4497 <indexterm>
4498 <primary>binary string</primary>
4499 <secondary>length</secondary>
4500 </indexterm>
4501 <indexterm>
4502 <primary>length</primary>
4503 <secondary sortas="binary string">of a binary string</secondary>
4504 <see>binary strings, length</see>
4505 </indexterm>
4506 <function>length</function> ( <type>bytea</type> )
4507 <returnvalue>integer</returnvalue>
4508 </para>
4509 <para>
4510 Returns the number of bytes in the binary string.
4511 </para>
4512 <para>
4513 <literal>length('\x1234567890'::bytea)</literal>
4514 <returnvalue>5</returnvalue>
4515 </para></entry>
4516 </row>
4518 <row>
4519 <entry role="func_table_entry"><para role="func_signature">
4520 <function>length</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4521 <parameter>encoding</parameter> <type>name</type> )
4522 <returnvalue>integer</returnvalue>
4523 </para>
4524 <para>
4525 Returns the number of characters in the binary string, assuming
4526 that it is text in the given <parameter>encoding</parameter>.
4527 </para>
4528 <para>
4529 <literal>length('jose'::bytea, 'UTF8')</literal>
4530 <returnvalue>4</returnvalue>
4531 </para></entry>
4532 </row>
4534 <row>
4535 <entry role="func_table_entry"><para role="func_signature">
4536 <indexterm>
4537 <primary>md5</primary>
4538 </indexterm>
4539 <function>md5</function> ( <type>bytea</type> )
4540 <returnvalue>text</returnvalue>
4541 </para>
4542 <para>
4543 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
4544 the binary string, with the result written in hexadecimal.
4545 </para>
4546 <para>
4547 <literal>md5('Th\000omas'::bytea)</literal>
4548 <returnvalue>8ab2d3c9689aaf18&zwsp;b4958c334c82d8b1</returnvalue>
4549 </para></entry>
4550 </row>
4552 <row>
4553 <entry role="func_table_entry"><para role="func_signature">
4554 <indexterm>
4555 <primary>set_bit</primary>
4556 </indexterm>
4557 <function>set_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4558 <parameter>n</parameter> <type>bigint</type>,
4559 <parameter>newvalue</parameter> <type>integer</type> )
4560 <returnvalue>bytea</returnvalue>
4561 </para>
4562 <para>
4563 Sets <link linkend="functions-zerobased-note">n'th</link> bit in
4564 binary string to <parameter>newvalue</parameter>.
4565 </para>
4566 <para>
4567 <literal>set_bit('\x1234567890'::bytea, 30, 0)</literal>
4568 <returnvalue>\x1234563890</returnvalue>
4569 </para></entry>
4570 </row>
4572 <row>
4573 <entry role="func_table_entry"><para role="func_signature">
4574 <indexterm>
4575 <primary>set_byte</primary>
4576 </indexterm>
4577 <function>set_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4578 <parameter>n</parameter> <type>integer</type>,
4579 <parameter>newvalue</parameter> <type>integer</type> )
4580 <returnvalue>bytea</returnvalue>
4581 </para>
4582 <para>
4583 Sets <link linkend="functions-zerobased-note">n'th</link> byte in
4584 binary string to <parameter>newvalue</parameter>.
4585 </para>
4586 <para>
4587 <literal>set_byte('\x1234567890'::bytea, 4, 64)</literal>
4588 <returnvalue>\x1234567840</returnvalue>
4589 </para></entry>
4590 </row>
4592 <row>
4593 <entry role="func_table_entry"><para role="func_signature">
4594 <indexterm>
4595 <primary>sha224</primary>
4596 </indexterm>
4597 <function>sha224</function> ( <type>bytea</type> )
4598 <returnvalue>bytea</returnvalue>
4599 </para>
4600 <para>
4601 Computes the SHA-224 <link linkend="functions-hash-note">hash</link>
4602 of the binary string.
4603 </para>
4604 <para>
4605 <literal>sha224('abc'::bytea)</literal>
4606 <returnvalue>\x23097d223405d8228642a477bda2&zwsp;55b32aadbce4bda0b3f7e36c9da7</returnvalue>
4607 </para></entry>
4608 </row>
4610 <row>
4611 <entry role="func_table_entry"><para role="func_signature">
4612 <indexterm>
4613 <primary>sha256</primary>
4614 </indexterm>
4615 <function>sha256</function> ( <type>bytea</type> )
4616 <returnvalue>bytea</returnvalue>
4617 </para>
4618 <para>
4619 Computes the SHA-256 <link linkend="functions-hash-note">hash</link>
4620 of the binary string.
4621 </para>
4622 <para>
4623 <literal>sha256('abc'::bytea)</literal>
4624 <returnvalue>\xba7816bf8f01cfea414140de5dae2223&zwsp;b00361a396177a9cb410ff61f20015ad</returnvalue>
4625 </para></entry>
4626 </row>
4628 <row>
4629 <entry role="func_table_entry"><para role="func_signature">
4630 <indexterm>
4631 <primary>sha384</primary>
4632 </indexterm>
4633 <function>sha384</function> ( <type>bytea</type> )
4634 <returnvalue>bytea</returnvalue>
4635 </para>
4636 <para>
4637 Computes the SHA-384 <link linkend="functions-hash-note">hash</link>
4638 of the binary string.
4639 </para>
4640 <para>
4641 <literal>sha384('abc'::bytea)</literal>
4642 <returnvalue>\xcb00753f45a35e8bb5a03d699ac65007&zwsp;272c32ab0eded1631a8b605a43ff5bed&zwsp;8086072ba1e7cc2358baeca134c825a7</returnvalue>
4643 </para></entry>
4644 </row>
4646 <row>
4647 <entry role="func_table_entry"><para role="func_signature">
4648 <indexterm>
4649 <primary>sha512</primary>
4650 </indexterm>
4651 <function>sha512</function> ( <type>bytea</type> )
4652 <returnvalue>bytea</returnvalue>
4653 </para>
4654 <para>
4655 Computes the SHA-512 <link linkend="functions-hash-note">hash</link>
4656 of the binary string.
4657 </para>
4658 <para>
4659 <literal>sha512('abc'::bytea)</literal>
4660 <returnvalue>\xddaf35a193617abacc417349ae204131&zwsp;12e6fa4e89a97ea20a9eeee64b55d39a&zwsp;2192992a274fc1a836ba3c23a3feebbd&zwsp;454d4423643ce80e2a9ac94fa54ca49f</returnvalue>
4661 </para></entry>
4662 </row>
4664 <row>
4665 <entry role="func_table_entry"><para role="func_signature">
4666 <indexterm>
4667 <primary>substr</primary>
4668 </indexterm>
4669 <function>substr</function> ( <parameter>bytes</parameter> <type>bytea</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
4670 <returnvalue>bytea</returnvalue>
4671 </para>
4672 <para>
4673 Extracts the substring of <parameter>bytes</parameter> starting at
4674 the <parameter>start</parameter>'th byte,
4675 and extending for <parameter>count</parameter> bytes if that is
4676 specified. (Same
4677 as <literal>substring(<parameter>bytes</parameter>
4678 from <parameter>start</parameter>
4679 for <parameter>count</parameter>)</literal>.)
4680 </para>
4681 <para>
4682 <literal>substr('\x1234567890'::bytea, 3, 2)</literal>
4683 <returnvalue>\x5678</returnvalue>
4684 </para></entry>
4685 </row>
4686 </tbody>
4687 </tgroup>
4688 </table>
4690 <para id="functions-zerobased-note">
4691 Functions <function>get_byte</function> and <function>set_byte</function>
4692 number the first byte of a binary string as byte 0.
4693 Functions <function>get_bit</function> and <function>set_bit</function>
4694 number bits from the right within each byte; for example bit 0 is the least
4695 significant bit of the first byte, and bit 15 is the most significant bit
4696 of the second byte.
4697 </para>
4699 <para id="functions-hash-note">
4700 For historical reasons, the function <function>md5</function>
4701 returns a hex-encoded value of type <type>text</type> whereas the SHA-2
4702 functions return type <type>bytea</type>. Use the functions
4703 <link linkend="function-encode"><function>encode</function></link>
4704 and <link linkend="function-decode"><function>decode</function></link> to
4705 convert between the two. For example write <literal>encode(sha256('abc'),
4706 'hex')</literal> to get a hex-encoded text representation,
4707 or <literal>decode(md5('abc'), 'hex')</literal> to get
4708 a <type>bytea</type> value.
4709 </para>
4711 <para>
4712 <indexterm>
4713 <primary>character string</primary>
4714 <secondary>converting to binary string</secondary>
4715 </indexterm>
4716 <indexterm>
4717 <primary>binary string</primary>
4718 <secondary>converting to character string</secondary>
4719 </indexterm>
4720 Functions for converting strings between different character sets
4721 (encodings), and for representing arbitrary binary data in textual
4722 form, are shown in
4723 <xref linkend="functions-binarystring-conversions"/>. For these
4724 functions, an argument or result of type <type>text</type> is expressed
4725 in the database's default encoding, while arguments or results of
4726 type <type>bytea</type> are in an encoding named by another argument.
4727 </para>
4729 <table id="functions-binarystring-conversions">
4730 <title>Text/Binary String Conversion Functions</title>
4731 <tgroup cols="1">
4732 <thead>
4733 <row>
4734 <entry role="func_table_entry"><para role="func_signature">
4735 Function
4736 </para>
4737 <para>
4738 Description
4739 </para>
4740 <para>
4741 Example(s)
4742 </para></entry>
4743 </row>
4744 </thead>
4746 <tbody>
4747 <row>
4748 <entry role="func_table_entry"><para role="func_signature">
4749 <indexterm>
4750 <primary>convert</primary>
4751 </indexterm>
4752 <function>convert</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4753 <parameter>src_encoding</parameter> <type>name</type>,
4754 <parameter>dest_encoding</parameter> <type>name</type> )
4755 <returnvalue>bytea</returnvalue>
4756 </para>
4757 <para>
4758 Converts a binary string representing text in
4759 encoding <parameter>src_encoding</parameter>
4760 to a binary string in encoding <parameter>dest_encoding</parameter>
4761 (see <xref linkend="multibyte-conversions-supported"/> for
4762 available conversions).
4763 </para>
4764 <para>
4765 <literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal>
4766 <returnvalue>\x746578745f696e5f75746638</returnvalue>
4767 </para></entry>
4768 </row>
4770 <row>
4771 <entry role="func_table_entry"><para role="func_signature">
4772 <indexterm>
4773 <primary>convert_from</primary>
4774 </indexterm>
4775 <function>convert_from</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4776 <parameter>src_encoding</parameter> <type>name</type> )
4777 <returnvalue>text</returnvalue>
4778 </para>
4779 <para>
4780 Converts a binary string representing text in
4781 encoding <parameter>src_encoding</parameter>
4782 to <type>text</type> in the database encoding
4783 (see <xref linkend="multibyte-conversions-supported"/> for
4784 available conversions).
4785 </para>
4786 <para>
4787 <literal>convert_from('text_in_utf8', 'UTF8')</literal>
4788 <returnvalue>text_in_utf8</returnvalue>
4789 </para></entry>
4790 </row>
4792 <row>
4793 <entry role="func_table_entry"><para role="func_signature">
4794 <indexterm>
4795 <primary>convert_to</primary>
4796 </indexterm>
4797 <function>convert_to</function> ( <parameter>string</parameter> <type>text</type>,
4798 <parameter>dest_encoding</parameter> <type>name</type> )
4799 <returnvalue>bytea</returnvalue>
4800 </para>
4801 <para>
4802 Converts a <type>text</type> string (in the database encoding) to a
4803 binary string encoded in encoding <parameter>dest_encoding</parameter>
4804 (see <xref linkend="multibyte-conversions-supported"/> for
4805 available conversions).
4806 </para>
4807 <para>
4808 <literal>convert_to('some_text', 'UTF8')</literal>
4809 <returnvalue>\x736f6d655f74657874</returnvalue>
4810 </para></entry>
4811 </row>
4813 <row>
4814 <entry role="func_table_entry"><para role="func_signature">
4815 <indexterm id="function-encode">
4816 <primary>encode</primary>
4817 </indexterm>
4818 <function>encode</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4819 <parameter>format</parameter> <type>text</type> )
4820 <returnvalue>text</returnvalue>
4821 </para>
4822 <para>
4823 Encodes binary data into a textual representation; supported
4824 <parameter>format</parameter> values are:
4825 <link linkend="encode-format-base64"><literal>base64</literal></link>,
4826 <link linkend="encode-format-escape"><literal>escape</literal></link>,
4827 <link linkend="encode-format-hex"><literal>hex</literal></link>.
4828 </para>
4829 <para>
4830 <literal>encode('123\000\001', 'base64')</literal>
4831 <returnvalue>MTIzAAE=</returnvalue>
4832 </para></entry>
4833 </row>
4835 <row>
4836 <entry role="func_table_entry"><para role="func_signature">
4837 <indexterm id="function-decode">
4838 <primary>decode</primary>
4839 </indexterm>
4840 <function>decode</function> ( <parameter>string</parameter> <type>text</type>,
4841 <parameter>format</parameter> <type>text</type> )
4842 <returnvalue>bytea</returnvalue>
4843 </para>
4844 <para>
4845 Decodes binary data from a textual representation; supported
4846 <parameter>format</parameter> values are the same as
4847 for <function>encode</function>.
4848 </para>
4849 <para>
4850 <literal>decode('MTIzAAE=', 'base64')</literal>
4851 <returnvalue>\x3132330001</returnvalue>
4852 </para></entry>
4853 </row>
4854 </tbody>
4855 </tgroup>
4856 </table>
4858 <para>
4859 The <function>encode</function> and <function>decode</function>
4860 functions support the following textual formats:
4862 <variablelist>
4863 <varlistentry id="encode-format-base64">
4864 <term>base64
4865 <indexterm>
4866 <primary>base64 format</primary>
4867 </indexterm></term>
4868 <listitem>
4869 <para>
4870 The <literal>base64</literal> format is that
4871 of <ulink url="https://tools.ietf.org/html/rfc2045#section-6.8">RFC
4872 2045 Section 6.8</ulink>. As per the <acronym>RFC</acronym>, encoded lines are
4873 broken at 76 characters. However instead of the MIME CRLF
4874 end-of-line marker, only a newline is used for end-of-line.
4875 The <function>decode</function> function ignores carriage-return,
4876 newline, space, and tab characters. Otherwise, an error is
4877 raised when <function>decode</function> is supplied invalid
4878 base64 data &mdash; including when trailing padding is incorrect.
4879 </para>
4880 </listitem>
4881 </varlistentry>
4883 <varlistentry id="encode-format-escape">
4884 <term>escape
4885 <indexterm>
4886 <primary>escape format</primary>
4887 </indexterm></term>
4888 <listitem>
4889 <para>
4890 The <literal>escape</literal> format converts zero bytes and
4891 bytes with the high bit set into octal escape sequences
4892 (<literal>\</literal><replaceable>nnn</replaceable>), and it doubles
4893 backslashes. Other byte values are represented literally.
4894 The <function>decode</function> function will raise an error if a
4895 backslash is not followed by either a second backslash or three
4896 octal digits; it accepts other byte values unchanged.
4897 </para>
4898 </listitem>
4899 </varlistentry>
4901 <varlistentry id="encode-format-hex">
4902 <term>hex
4903 <indexterm>
4904 <primary>hex format</primary>
4905 </indexterm></term>
4906 <listitem>
4907 <para>
4908 The <literal>hex</literal> format represents each 4 bits of
4909 data as one hexadecimal digit, <literal>0</literal>
4910 through <literal>f</literal>, writing the higher-order digit of
4911 each byte first. The <function>encode</function> function outputs
4912 the <literal>a</literal>-<literal>f</literal> hex digits in lower
4913 case. Because the smallest unit of data is 8 bits, there are
4914 always an even number of characters returned
4915 by <function>encode</function>.
4916 The <function>decode</function> function
4917 accepts the <literal>a</literal>-<literal>f</literal> characters in
4918 either upper or lower case. An error is raised
4919 when <function>decode</function> is given invalid hex data
4920 &mdash; including when given an odd number of characters.
4921 </para>
4922 </listitem>
4923 </varlistentry>
4924 </variablelist>
4925 </para>
4927 <para>
4928 See also the aggregate function <function>string_agg</function> in
4929 <xref linkend="functions-aggregate"/> and the large object functions
4930 in <xref linkend="lo-funcs"/>.
4931 </para>
4932 </sect1>
4935 <sect1 id="functions-bitstring">
4936 <title>Bit String Functions and Operators</title>
4938 <indexterm zone="functions-bitstring">
4939 <primary>bit strings</primary>
4940 <secondary>functions</secondary>
4941 </indexterm>
4943 <para>
4944 This section describes functions and operators for examining and
4945 manipulating bit strings, that is values of the types
4946 <type>bit</type> and <type>bit varying</type>. (While only
4947 type <type>bit</type> is mentioned in these tables, values of
4948 type <type>bit varying</type> can be used interchangeably.)
4949 Bit strings support the usual comparison operators shown in
4950 <xref linkend="functions-comparison-op-table"/>, as well as the
4951 operators shown in <xref linkend="functions-bit-string-op-table"/>.
4952 </para>
4954 <table id="functions-bit-string-op-table">
4955 <title>Bit String Operators</title>
4956 <tgroup cols="1">
4957 <thead>
4958 <row>
4959 <entry role="func_table_entry"><para role="func_signature">
4960 Operator
4961 </para>
4962 <para>
4963 Description
4964 </para>
4965 <para>
4966 Example(s)
4967 </para></entry>
4968 </row>
4969 </thead>
4971 <tbody>
4972 <row>
4973 <entry role="func_table_entry"><para role="func_signature">
4974 <type>bit</type> <literal>||</literal> <type>bit</type>
4975 <returnvalue>bit</returnvalue>
4976 </para>
4977 <para>
4978 Concatenation
4979 </para>
4980 <para>
4981 <literal>B'10001' || B'011'</literal>
4982 <returnvalue>10001011</returnvalue>
4983 </para></entry>
4984 </row>
4986 <row>
4987 <entry role="func_table_entry"><para role="func_signature">
4988 <type>bit</type> <literal>&amp;</literal> <type>bit</type>
4989 <returnvalue>bit</returnvalue>
4990 </para>
4991 <para>
4992 Bitwise AND (inputs must be of equal length)
4993 </para>
4994 <para>
4995 <literal>B'10001' &amp; B'01101'</literal>
4996 <returnvalue>00001</returnvalue>
4997 </para></entry>
4998 </row>
5000 <row>
5001 <entry role="func_table_entry"><para role="func_signature">
5002 <type>bit</type> <literal>|</literal> <type>bit</type>
5003 <returnvalue>bit</returnvalue>
5004 </para>
5005 <para>
5006 Bitwise OR (inputs must be of equal length)
5007 </para>
5008 <para>
5009 <literal>B'10001' | B'01101'</literal>
5010 <returnvalue>11101</returnvalue>
5011 </para></entry>
5012 </row>
5014 <row>
5015 <entry role="func_table_entry"><para role="func_signature">
5016 <type>bit</type> <literal>#</literal> <type>bit</type>
5017 <returnvalue>bit</returnvalue>
5018 </para>
5019 <para>
5020 Bitwise exclusive OR (inputs must be of equal length)
5021 </para>
5022 <para>
5023 <literal>B'10001' # B'01101'</literal>
5024 <returnvalue>11100</returnvalue>
5025 </para></entry>
5026 </row>
5028 <row>
5029 <entry role="func_table_entry"><para role="func_signature">
5030 <literal>~</literal> <type>bit</type>
5031 <returnvalue>bit</returnvalue>
5032 </para>
5033 <para>
5034 Bitwise NOT
5035 </para>
5036 <para>
5037 <literal>~ B'10001'</literal>
5038 <returnvalue>01110</returnvalue>
5039 </para></entry>
5040 </row>
5042 <row>
5043 <entry role="func_table_entry"><para role="func_signature">
5044 <type>bit</type> <literal>&lt;&lt;</literal> <type>integer</type>
5045 <returnvalue>bit</returnvalue>
5046 </para>
5047 <para>
5048 Bitwise shift left
5049 (string length is preserved)
5050 </para>
5051 <para>
5052 <literal>B'10001' &lt;&lt; 3</literal>
5053 <returnvalue>01000</returnvalue>
5054 </para></entry>
5055 </row>
5057 <row>
5058 <entry role="func_table_entry"><para role="func_signature">
5059 <type>bit</type> <literal>&gt;&gt;</literal> <type>integer</type>
5060 <returnvalue>bit</returnvalue>
5061 </para>
5062 <para>
5063 Bitwise shift right
5064 (string length is preserved)
5065 </para>
5066 <para>
5067 <literal>B'10001' &gt;&gt; 2</literal>
5068 <returnvalue>00100</returnvalue>
5069 </para></entry>
5070 </row>
5071 </tbody>
5072 </tgroup>
5073 </table>
5075 <para>
5076 Some of the functions available for binary strings are also available
5077 for bit strings, as shown in <xref linkend="functions-bit-string-table"/>.
5078 </para>
5080 <table id="functions-bit-string-table">
5081 <title>Bit String Functions</title>
5082 <tgroup cols="1">
5083 <thead>
5084 <row>
5085 <entry role="func_table_entry"><para role="func_signature">
5086 Function
5087 </para>
5088 <para>
5089 Description
5090 </para>
5091 <para>
5092 Example(s)
5093 </para></entry>
5094 </row>
5095 </thead>
5097 <tbody>
5098 <row>
5099 <entry role="func_table_entry"><para role="func_signature">
5100 <indexterm>
5101 <primary>bit_count</primary>
5102 </indexterm>
5103 <function>bit_count</function> ( <type>bit</type> )
5104 <returnvalue>bigint</returnvalue>
5105 </para>
5106 <para>
5107 Returns the number of bits set in the bit string (also known as
5108 <quote>popcount</quote>).
5109 </para>
5110 <para>
5111 <literal>bit_count(B'10111')</literal>
5112 <returnvalue>4</returnvalue>
5113 </para></entry>
5114 </row>
5116 <row>
5117 <entry role="func_table_entry"><para role="func_signature">
5118 <indexterm>
5119 <primary>bit_length</primary>
5120 </indexterm>
5121 <function>bit_length</function> ( <type>bit</type> )
5122 <returnvalue>integer</returnvalue>
5123 </para>
5124 <para>
5125 Returns number of bits in the bit string.
5126 </para>
5127 <para>
5128 <literal>bit_length(B'10111')</literal>
5129 <returnvalue>5</returnvalue>
5130 </para></entry>
5131 </row>
5133 <row>
5134 <entry role="func_table_entry"><para role="func_signature">
5135 <indexterm>
5136 <primary>length</primary>
5137 </indexterm>
5138 <indexterm>
5139 <primary>bit string</primary>
5140 <secondary>length</secondary>
5141 </indexterm>
5142 <function>length</function> ( <type>bit</type> )
5143 <returnvalue>integer</returnvalue>
5144 </para>
5145 <para>
5146 Returns number of bits in the bit string.
5147 </para>
5148 <para>
5149 <literal>length(B'10111')</literal>
5150 <returnvalue>5</returnvalue>
5151 </para></entry>
5152 </row>
5154 <row>
5155 <entry role="func_table_entry"><para role="func_signature">
5156 <indexterm>
5157 <primary>octet_length</primary>
5158 </indexterm>
5159 <function>octet_length</function> ( <type>bit</type> )
5160 <returnvalue>integer</returnvalue>
5161 </para>
5162 <para>
5163 Returns number of bytes in the bit string.
5164 </para>
5165 <para>
5166 <literal>octet_length(B'1011111011')</literal>
5167 <returnvalue>2</returnvalue>
5168 </para></entry>
5169 </row>
5171 <row>
5172 <entry role="func_table_entry"><para role="func_signature">
5173 <indexterm>
5174 <primary>overlay</primary>
5175 </indexterm>
5176 <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> )
5177 <returnvalue>bit</returnvalue>
5178 </para>
5179 <para>
5180 Replaces the substring of <parameter>bits</parameter> that starts at
5181 the <parameter>start</parameter>'th bit and extends
5182 for <parameter>count</parameter> bits
5183 with <parameter>newsubstring</parameter>.
5184 If <parameter>count</parameter> is omitted, it defaults to the length
5185 of <parameter>newsubstring</parameter>.
5186 </para>
5187 <para>
5188 <literal>overlay(B'01010101010101010' placing B'11111' from 2 for 3)</literal>
5189 <returnvalue>0111110101010101010</returnvalue>
5190 </para></entry>
5191 </row>
5193 <row>
5194 <entry role="func_table_entry"><para role="func_signature">
5195 <indexterm>
5196 <primary>position</primary>
5197 </indexterm>
5198 <function>position</function> ( <parameter>substring</parameter> <type>bit</type> <literal>IN</literal> <parameter>bits</parameter> <type>bit</type> )
5199 <returnvalue>integer</returnvalue>
5200 </para>
5201 <para>
5202 Returns first starting index of the specified <parameter>substring</parameter>
5203 within <parameter>bits</parameter>, or zero if it's not present.
5204 </para>
5205 <para>
5206 <literal>position(B'010' in B'000001101011')</literal>
5207 <returnvalue>8</returnvalue>
5208 </para></entry>
5209 </row>
5211 <row>
5212 <entry role="func_table_entry"><para role="func_signature">
5213 <indexterm>
5214 <primary>substring</primary>
5215 </indexterm>
5216 <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> )
5217 <returnvalue>bit</returnvalue>
5218 </para>
5219 <para>
5220 Extracts the substring of <parameter>bits</parameter> starting at
5221 the <parameter>start</parameter>'th bit if that is specified,
5222 and stopping after <parameter>count</parameter> bits if that is
5223 specified. Provide at least one of <parameter>start</parameter>
5224 and <parameter>count</parameter>.
5225 </para>
5226 <para>
5227 <literal>substring(B'110010111111' from 3 for 2)</literal>
5228 <returnvalue>00</returnvalue>
5229 </para></entry>
5230 </row>
5232 <row>
5233 <entry role="func_table_entry"><para role="func_signature">
5234 <indexterm>
5235 <primary>get_bit</primary>
5236 </indexterm>
5237 <function>get_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5238 <parameter>n</parameter> <type>integer</type> )
5239 <returnvalue>integer</returnvalue>
5240 </para>
5241 <para>
5242 Extracts <parameter>n</parameter>'th bit
5243 from bit string; the first (leftmost) bit is bit 0.
5244 </para>
5245 <para>
5246 <literal>get_bit(B'101010101010101010', 6)</literal>
5247 <returnvalue>1</returnvalue>
5248 </para></entry>
5249 </row>
5251 <row>
5252 <entry role="func_table_entry"><para role="func_signature">
5253 <indexterm>
5254 <primary>set_bit</primary>
5255 </indexterm>
5256 <function>set_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5257 <parameter>n</parameter> <type>integer</type>,
5258 <parameter>newvalue</parameter> <type>integer</type> )
5259 <returnvalue>bit</returnvalue>
5260 </para>
5261 <para>
5262 Sets <parameter>n</parameter>'th bit in
5263 bit string to <parameter>newvalue</parameter>;
5264 the first (leftmost) bit is bit 0.
5265 </para>
5266 <para>
5267 <literal>set_bit(B'101010101010101010', 6, 0)</literal>
5268 <returnvalue>101010001010101010</returnvalue>
5269 </para></entry>
5270 </row>
5271 </tbody>
5272 </tgroup>
5273 </table>
5275 <para>
5276 In addition, it is possible to cast integral values to and from type
5277 <type>bit</type>.
5278 Casting an integer to <type>bit(n)</type> copies the rightmost
5279 <literal>n</literal> bits. Casting an integer to a bit string width wider
5280 than the integer itself will sign-extend on the left.
5281 Some examples:
5282 <programlisting>
5283 44::bit(10) <lineannotation>0000101100</lineannotation>
5284 44::bit(3) <lineannotation>100</lineannotation>
5285 cast(-44 as bit(12)) <lineannotation>111111010100</lineannotation>
5286 '1110'::bit(4)::integer <lineannotation>14</lineannotation>
5287 </programlisting>
5288 Note that casting to just <quote>bit</quote> means casting to
5289 <literal>bit(1)</literal>, and so will deliver only the least significant
5290 bit of the integer.
5291 </para>
5292 </sect1>
5295 <sect1 id="functions-matching">
5296 <title>Pattern Matching</title>
5298 <indexterm zone="functions-matching">
5299 <primary>pattern matching</primary>
5300 </indexterm>
5302 <para>
5303 There are three separate approaches to pattern matching provided
5304 by <productname>PostgreSQL</productname>: the traditional
5305 <acronym>SQL</acronym> <function>LIKE</function> operator, the
5306 more recent <function>SIMILAR TO</function> operator (added in
5307 SQL:1999), and <acronym>POSIX</acronym>-style regular
5308 expressions. Aside from the basic <quote>does this string match
5309 this pattern?</quote> operators, functions are available to extract
5310 or replace matching substrings and to split a string at matching
5311 locations.
5312 </para>
5314 <tip>
5315 <para>
5316 If you have pattern matching needs that go beyond this,
5317 consider writing a user-defined function in Perl or Tcl.
5318 </para>
5319 </tip>
5321 <caution>
5322 <para>
5323 While most regular-expression searches can be executed very quickly,
5324 regular expressions can be contrived that take arbitrary amounts of
5325 time and memory to process. Be wary of accepting regular-expression
5326 search patterns from hostile sources. If you must do so, it is
5327 advisable to impose a statement timeout.
5328 </para>
5330 <para>
5331 Searches using <function>SIMILAR TO</function> patterns have the same
5332 security hazards, since <function>SIMILAR TO</function> provides many
5333 of the same capabilities as <acronym>POSIX</acronym>-style regular
5334 expressions.
5335 </para>
5337 <para>
5338 <function>LIKE</function> searches, being much simpler than the other
5339 two options, are safer to use with possibly-hostile pattern sources.
5340 </para>
5341 </caution>
5343 <para>
5344 The pattern matching operators of all three kinds do not support
5345 nondeterministic collations. If required, apply a different collation to
5346 the expression to work around this limitation.
5347 </para>
5349 <sect2 id="functions-like">
5350 <title><function>LIKE</function></title>
5352 <indexterm>
5353 <primary>LIKE</primary>
5354 </indexterm>
5356 <synopsis>
5357 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5358 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5359 </synopsis>
5361 <para>
5362 The <function>LIKE</function> expression returns true if the
5363 <replaceable>string</replaceable> matches the supplied
5364 <replaceable>pattern</replaceable>. (As
5365 expected, the <function>NOT LIKE</function> expression returns
5366 false if <function>LIKE</function> returns true, and vice versa.
5367 An equivalent expression is
5368 <literal>NOT (<replaceable>string</replaceable> LIKE
5369 <replaceable>pattern</replaceable>)</literal>.)
5370 </para>
5372 <para>
5373 If <replaceable>pattern</replaceable> does not contain percent
5374 signs or underscores, then the pattern only represents the string
5375 itself; in that case <function>LIKE</function> acts like the
5376 equals operator. An underscore (<literal>_</literal>) in
5377 <replaceable>pattern</replaceable> stands for (matches) any single
5378 character; a percent sign (<literal>%</literal>) matches any sequence
5379 of zero or more characters.
5380 </para>
5382 <para>
5383 Some examples:
5384 <programlisting>
5385 'abc' LIKE 'abc' <lineannotation>true</lineannotation>
5386 'abc' LIKE 'a%' <lineannotation>true</lineannotation>
5387 'abc' LIKE '_b_' <lineannotation>true</lineannotation>
5388 'abc' LIKE 'c' <lineannotation>false</lineannotation>
5389 </programlisting>
5390 </para>
5392 <para>
5393 <function>LIKE</function> pattern matching always covers the entire
5394 string. Therefore, if it's desired to match a sequence anywhere within
5395 a string, the pattern must start and end with a percent sign.
5396 </para>
5398 <para>
5399 To match a literal underscore or percent sign without matching
5400 other characters, the respective character in
5401 <replaceable>pattern</replaceable> must be
5402 preceded by the escape character. The default escape
5403 character is the backslash but a different one can be selected by
5404 using the <literal>ESCAPE</literal> clause. To match the escape
5405 character itself, write two escape characters.
5406 </para>
5408 <note>
5409 <para>
5410 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
5411 any backslashes you write in literal string constants will need to be
5412 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
5413 </para>
5414 </note>
5416 <para>
5417 It's also possible to select no escape character by writing
5418 <literal>ESCAPE ''</literal>. This effectively disables the
5419 escape mechanism, which makes it impossible to turn off the
5420 special meaning of underscore and percent signs in the pattern.
5421 </para>
5423 <para>
5424 According to the SQL standard, omitting <literal>ESCAPE</literal>
5425 means there is no escape character (rather than defaulting to a
5426 backslash), and a zero-length <literal>ESCAPE</literal> value is
5427 disallowed. <productname>PostgreSQL</productname>'s behavior in
5428 this regard is therefore slightly nonstandard.
5429 </para>
5431 <para>
5432 The key word <token>ILIKE</token> can be used instead of
5433 <token>LIKE</token> to make the match case-insensitive according
5434 to the active locale. This is not in the <acronym>SQL</acronym> standard but is a
5435 <productname>PostgreSQL</productname> extension.
5436 </para>
5438 <para>
5439 The operator <literal>~~</literal> is equivalent to
5440 <function>LIKE</function>, and <literal>~~*</literal> corresponds to
5441 <function>ILIKE</function>. There are also
5442 <literal>!~~</literal> and <literal>!~~*</literal> operators that
5443 represent <function>NOT LIKE</function> and <function>NOT
5444 ILIKE</function>, respectively. All of these operators are
5445 <productname>PostgreSQL</productname>-specific. You may see these
5446 operator names in <command>EXPLAIN</command> output and similar
5447 places, since the parser actually translates <function>LIKE</function>
5448 et al. to these operators.
5449 </para>
5451 <para>
5452 The phrases <function>LIKE</function>, <function>ILIKE</function>,
5453 <function>NOT LIKE</function>, and <function>NOT ILIKE</function> are
5454 generally treated as operators
5455 in <productname>PostgreSQL</productname> syntax; for example they can
5456 be used in <replaceable>expression</replaceable>
5457 <replaceable>operator</replaceable> ANY
5458 (<replaceable>subquery</replaceable>) constructs, although
5459 an <literal>ESCAPE</literal> clause cannot be included there. In some
5460 obscure cases it may be necessary to use the underlying operator names
5461 instead.
5462 </para>
5464 <para>
5465 Also see the starts-with operator <literal>^@</literal> and the
5466 corresponding <function>starts_with()</function> function, which are
5467 useful in cases where simply matching the beginning of a string is
5468 needed.
5469 </para>
5470 </sect2>
5473 <sect2 id="functions-similarto-regexp">
5474 <title><function>SIMILAR TO</function> Regular Expressions</title>
5476 <indexterm>
5477 <primary>regular expression</primary>
5478 <!-- <seealso>pattern matching</seealso> breaks index build -->
5479 </indexterm>
5481 <indexterm>
5482 <primary>SIMILAR TO</primary>
5483 </indexterm>
5484 <indexterm>
5485 <primary>substring</primary>
5486 </indexterm>
5488 <synopsis>
5489 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5490 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5491 </synopsis>
5493 <para>
5494 The <function>SIMILAR TO</function> operator returns true or
5495 false depending on whether its pattern matches the given string.
5496 It is similar to <function>LIKE</function>, except that it
5497 interprets the pattern using the SQL standard's definition of a
5498 regular expression. SQL regular expressions are a curious cross
5499 between <function>LIKE</function> notation and common (POSIX) regular
5500 expression notation.
5501 </para>
5503 <para>
5504 Like <function>LIKE</function>, the <function>SIMILAR TO</function>
5505 operator succeeds only if its pattern matches the entire string;
5506 this is unlike common regular expression behavior where the pattern
5507 can match any part of the string.
5508 Also like
5509 <function>LIKE</function>, <function>SIMILAR TO</function> uses
5510 <literal>_</literal> and <literal>%</literal> as wildcard characters denoting
5511 any single character and any string, respectively (these are
5512 comparable to <literal>.</literal> and <literal>.*</literal> in POSIX regular
5513 expressions).
5514 </para>
5516 <para>
5517 In addition to these facilities borrowed from <function>LIKE</function>,
5518 <function>SIMILAR TO</function> supports these pattern-matching
5519 metacharacters borrowed from POSIX regular expressions:
5521 <itemizedlist>
5522 <listitem>
5523 <para>
5524 <literal>|</literal> denotes alternation (either of two alternatives).
5525 </para>
5526 </listitem>
5527 <listitem>
5528 <para>
5529 <literal>*</literal> denotes repetition of the previous item zero
5530 or more times.
5531 </para>
5532 </listitem>
5533 <listitem>
5534 <para>
5535 <literal>+</literal> denotes repetition of the previous item one
5536 or more times.
5537 </para>
5538 </listitem>
5539 <listitem>
5540 <para>
5541 <literal>?</literal> denotes repetition of the previous item zero
5542 or one time.
5543 </para>
5544 </listitem>
5545 <listitem>
5546 <para>
5547 <literal>{</literal><replaceable>m</replaceable><literal>}</literal> denotes repetition
5548 of the previous item exactly <replaceable>m</replaceable> times.
5549 </para>
5550 </listitem>
5551 <listitem>
5552 <para>
5553 <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> denotes repetition
5554 of the previous item <replaceable>m</replaceable> or more times.
5555 </para>
5556 </listitem>
5557 <listitem>
5558 <para>
5559 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
5560 denotes repetition of the previous item at least <replaceable>m</replaceable> and
5561 not more than <replaceable>n</replaceable> times.
5562 </para>
5563 </listitem>
5564 <listitem>
5565 <para>
5566 Parentheses <literal>()</literal> can be used to group items into
5567 a single logical item.
5568 </para>
5569 </listitem>
5570 <listitem>
5571 <para>
5572 A bracket expression <literal>[...]</literal> specifies a character
5573 class, just as in POSIX regular expressions.
5574 </para>
5575 </listitem>
5576 </itemizedlist>
5578 Notice that the period (<literal>.</literal>) is not a metacharacter
5579 for <function>SIMILAR TO</function>.
5580 </para>
5582 <para>
5583 As with <function>LIKE</function>, a backslash disables the special
5584 meaning of any of these metacharacters. A different escape character
5585 can be specified with <literal>ESCAPE</literal>, or the escape
5586 capability can be disabled by writing <literal>ESCAPE ''</literal>.
5587 </para>
5589 <para>
5590 According to the SQL standard, omitting <literal>ESCAPE</literal>
5591 means there is no escape character (rather than defaulting to a
5592 backslash), and a zero-length <literal>ESCAPE</literal> value is
5593 disallowed. <productname>PostgreSQL</productname>'s behavior in
5594 this regard is therefore slightly nonstandard.
5595 </para>
5597 <para>
5598 Another nonstandard extension is that following the escape character
5599 with a letter or digit provides access to the escape sequences
5600 defined for POSIX regular expressions; see
5601 <xref linkend="posix-character-entry-escapes-table"/>,
5602 <xref linkend="posix-class-shorthand-escapes-table"/>, and
5603 <xref linkend="posix-constraint-escapes-table"/> below.
5604 </para>
5606 <para>
5607 Some examples:
5608 <programlisting>
5609 'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation>
5610 'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation>
5611 'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation>
5612 'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation>
5613 '-abc-' SIMILAR TO '%\mabc\M%' <lineannotation>true</lineannotation>
5614 'xabcy' SIMILAR TO '%\mabc\M%' <lineannotation>false</lineannotation>
5615 </programlisting>
5616 </para>
5618 <para>
5619 The <function>substring</function> function with three parameters
5620 provides extraction of a substring that matches an SQL
5621 regular expression pattern. The function can be written according
5622 to standard SQL syntax:
5623 <synopsis>
5624 substring(<replaceable>string</replaceable> similar <replaceable>pattern</replaceable> escape <replaceable>escape-character</replaceable>)
5625 </synopsis>
5626 or using the now obsolete SQL:1999 syntax:
5627 <synopsis>
5628 substring(<replaceable>string</replaceable> from <replaceable>pattern</replaceable> for <replaceable>escape-character</replaceable>)
5629 </synopsis>
5630 or as a plain three-argument function:
5631 <synopsis>
5632 substring(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>escape-character</replaceable>)
5633 </synopsis>
5634 As with <literal>SIMILAR TO</literal>, the
5635 specified pattern must match the entire data string, or else the
5636 function fails and returns null. To indicate the part of the
5637 pattern for which the matching data sub-string is of interest,
5638 the pattern should contain
5639 two occurrences of the escape character followed by a double quote
5640 (<literal>"</literal>). <!-- " font-lock sanity -->
5641 The text matching the portion of the pattern
5642 between these separators is returned when the match is successful.
5643 </para>
5645 <para>
5646 The escape-double-quote separators actually
5647 divide <function>substring</function>'s pattern into three independent
5648 regular expressions; for example, a vertical bar (<literal>|</literal>)
5649 in any of the three sections affects only that section. Also, the first
5650 and third of these regular expressions are defined to match the smallest
5651 possible amount of text, not the largest, when there is any ambiguity
5652 about how much of the data string matches which pattern. (In POSIX
5653 parlance, the first and third regular expressions are forced to be
5654 non-greedy.)
5655 </para>
5657 <para>
5658 As an extension to the SQL standard, <productname>PostgreSQL</productname>
5659 allows there to be just one escape-double-quote separator, in which case
5660 the third regular expression is taken as empty; or no separators, in which
5661 case the first and third regular expressions are taken as empty.
5662 </para>
5664 <para>
5665 Some examples, with <literal>#&quot;</literal> delimiting the return string:
5666 <programlisting>
5667 substring('foobar' similar '%#"o_b#"%' escape '#') <lineannotation>oob</lineannotation>
5668 substring('foobar' similar '#"o_b#"%' escape '#') <lineannotation>NULL</lineannotation>
5669 </programlisting>
5670 </para>
5671 </sect2>
5673 <sect2 id="functions-posix-regexp">
5674 <title><acronym>POSIX</acronym> Regular Expressions</title>
5676 <indexterm zone="functions-posix-regexp">
5677 <primary>regular expression</primary>
5678 <seealso>pattern matching</seealso>
5679 </indexterm>
5680 <indexterm>
5681 <primary>substring</primary>
5682 </indexterm>
5683 <indexterm>
5684 <primary>regexp_count</primary>
5685 </indexterm>
5686 <indexterm>
5687 <primary>regexp_instr</primary>
5688 </indexterm>
5689 <indexterm>
5690 <primary>regexp_like</primary>
5691 </indexterm>
5692 <indexterm>
5693 <primary>regexp_match</primary>
5694 </indexterm>
5695 <indexterm>
5696 <primary>regexp_matches</primary>
5697 </indexterm>
5698 <indexterm>
5699 <primary>regexp_replace</primary>
5700 </indexterm>
5701 <indexterm>
5702 <primary>regexp_split_to_table</primary>
5703 </indexterm>
5704 <indexterm>
5705 <primary>regexp_split_to_array</primary>
5706 </indexterm>
5707 <indexterm>
5708 <primary>regexp_substr</primary>
5709 </indexterm>
5711 <para>
5712 <xref linkend="functions-posix-table"/> lists the available
5713 operators for pattern matching using POSIX regular expressions.
5714 </para>
5716 <table id="functions-posix-table">
5717 <title>Regular Expression Match Operators</title>
5719 <tgroup cols="1">
5720 <thead>
5721 <row>
5722 <entry role="func_table_entry"><para role="func_signature">
5723 Operator
5724 </para>
5725 <para>
5726 Description
5727 </para>
5728 <para>
5729 Example(s)
5730 </para></entry>
5731 </row>
5732 </thead>
5734 <tbody>
5735 <row>
5736 <entry role="func_table_entry"><para role="func_signature">
5737 <type>text</type> <literal>~</literal> <type>text</type>
5738 <returnvalue>boolean</returnvalue>
5739 </para>
5740 <para>
5741 String matches regular expression, case sensitively
5742 </para>
5743 <para>
5744 <literal>'thomas' ~ 't.*ma'</literal>
5745 <returnvalue>t</returnvalue>
5746 </para></entry>
5747 </row>
5749 <row>
5750 <entry role="func_table_entry"><para role="func_signature">
5751 <type>text</type> <literal>~*</literal> <type>text</type>
5752 <returnvalue>boolean</returnvalue>
5753 </para>
5754 <para>
5755 String matches regular expression, case-insensitively
5756 </para>
5757 <para>
5758 <literal>'thomas' ~* 'T.*ma'</literal>
5759 <returnvalue>t</returnvalue>
5760 </para></entry>
5761 </row>
5763 <row>
5764 <entry role="func_table_entry"><para role="func_signature">
5765 <type>text</type> <literal>!~</literal> <type>text</type>
5766 <returnvalue>boolean</returnvalue>
5767 </para>
5768 <para>
5769 String does not match regular expression, case sensitively
5770 </para>
5771 <para>
5772 <literal>'thomas' !~ 't.*max'</literal>
5773 <returnvalue>t</returnvalue>
5774 </para></entry>
5775 </row>
5777 <row>
5778 <entry role="func_table_entry"><para role="func_signature">
5779 <type>text</type> <literal>!~*</literal> <type>text</type>
5780 <returnvalue>boolean</returnvalue>
5781 </para>
5782 <para>
5783 String does not match regular expression, case-insensitively
5784 </para>
5785 <para>
5786 <literal>'thomas' !~* 'T.*ma'</literal>
5787 <returnvalue>f</returnvalue>
5788 </para></entry>
5789 </row>
5790 </tbody>
5791 </tgroup>
5792 </table>
5794 <para>
5795 <acronym>POSIX</acronym> regular expressions provide a more
5796 powerful means for pattern matching than the <function>LIKE</function> and
5797 <function>SIMILAR TO</function> operators.
5798 Many Unix tools such as <command>egrep</command>,
5799 <command>sed</command>, or <command>awk</command> use a pattern
5800 matching language that is similar to the one described here.
5801 </para>
5803 <para>
5804 A regular expression is a character sequence that is an
5805 abbreviated definition of a set of strings (a <firstterm>regular
5806 set</firstterm>). A string is said to match a regular expression
5807 if it is a member of the regular set described by the regular
5808 expression. As with <function>LIKE</function>, pattern characters
5809 match string characters exactly unless they are special characters
5810 in the regular expression language &mdash; but regular expressions use
5811 different special characters than <function>LIKE</function> does.
5812 Unlike <function>LIKE</function> patterns, a
5813 regular expression is allowed to match anywhere within a string, unless
5814 the regular expression is explicitly anchored to the beginning or
5815 end of the string.
5816 </para>
5818 <para>
5819 Some examples:
5820 <programlisting>
5821 'abcd' ~ 'bc' <lineannotation>true</lineannotation>
5822 'abcd' ~ 'a.c' <lineannotation>true &mdash; dot matches any character</lineannotation>
5823 'abcd' ~ 'a.*d' <lineannotation>true &mdash; <literal>*</literal> repeats the preceding pattern item</lineannotation>
5824 'abcd' ~ '(b|x)' <lineannotation>true &mdash; <literal>|</literal> means OR, parentheses group</lineannotation>
5825 'abcd' ~ '^a' <lineannotation>true &mdash; <literal>^</literal> anchors to start of string</lineannotation>
5826 'abcd' ~ '^(b|c)' <lineannotation>false &mdash; would match except for anchoring</lineannotation>
5827 </programlisting>
5828 </para>
5830 <para>
5831 The <acronym>POSIX</acronym> pattern language is described in much
5832 greater detail below.
5833 </para>
5835 <para>
5836 The <function>substring</function> function with two parameters,
5837 <function>substring(<replaceable>string</replaceable> from
5838 <replaceable>pattern</replaceable>)</function>, provides extraction of a
5839 substring
5840 that matches a POSIX regular expression pattern. It returns null if
5841 there is no match, otherwise the first portion of the text that matched the
5842 pattern. But if the pattern contains any parentheses, the portion
5843 of the text that matched the first parenthesized subexpression (the
5844 one whose left parenthesis comes first) is
5845 returned. You can put parentheses around the whole expression
5846 if you want to use parentheses within it without triggering this
5847 exception. If you need parentheses in the pattern before the
5848 subexpression you want to extract, see the non-capturing parentheses
5849 described below.
5850 </para>
5852 <para>
5853 Some examples:
5854 <programlisting>
5855 substring('foobar' from 'o.b') <lineannotation>oob</lineannotation>
5856 substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation>
5857 </programlisting>
5858 </para>
5860 <para>
5861 The <function>regexp_count</function> function counts the number of
5862 places where a POSIX regular expression pattern matches a string.
5863 It has the syntax
5864 <function>regexp_count</function>(<replaceable>string</replaceable>,
5865 <replaceable>pattern</replaceable>
5866 <optional>, <replaceable>start</replaceable>
5867 <optional>, <replaceable>flags</replaceable>
5868 </optional></optional>).
5869 <replaceable>pattern</replaceable> is searched for
5870 in <replaceable>string</replaceable>, normally from the beginning of
5871 the string, but if the <replaceable>start</replaceable> parameter is
5872 provided then beginning from that character index.
5873 The <replaceable>flags</replaceable> parameter is an optional text
5874 string containing zero or more single-letter flags that change the
5875 function's behavior. For example, including <literal>i</literal> in
5876 <replaceable>flags</replaceable> specifies case-insensitive matching.
5877 Supported flags are described in
5878 <xref linkend="posix-embedded-options-table"/>.
5879 </para>
5881 <para>
5882 Some examples:
5883 <programlisting>
5884 regexp_count('ABCABCAXYaxy', 'A.') <lineannotation>3</lineannotation>
5885 regexp_count('ABCABCAXYaxy', 'A.', 1, 'i') <lineannotation>4</lineannotation>
5886 </programlisting>
5887 </para>
5889 <para>
5890 The <function>regexp_instr</function> function returns the starting or
5891 ending position of the <replaceable>N</replaceable>'th match of a
5892 POSIX regular expression pattern to a string, or zero if there is no
5893 such match. It has the syntax
5894 <function>regexp_instr</function>(<replaceable>string</replaceable>,
5895 <replaceable>pattern</replaceable>
5896 <optional>, <replaceable>start</replaceable>
5897 <optional>, <replaceable>N</replaceable>
5898 <optional>, <replaceable>endoption</replaceable>
5899 <optional>, <replaceable>flags</replaceable>
5900 <optional>, <replaceable>subexpr</replaceable>
5901 </optional></optional></optional></optional></optional>).
5902 <replaceable>pattern</replaceable> is searched for
5903 in <replaceable>string</replaceable>, normally from the beginning of
5904 the string, but if the <replaceable>start</replaceable> parameter is
5905 provided then beginning from that character index.
5906 If <replaceable>N</replaceable> is specified
5907 then the <replaceable>N</replaceable>'th match of the pattern
5908 is located, otherwise the first match is located.
5909 If the <replaceable>endoption</replaceable> parameter is omitted or
5910 specified as zero, the function returns the position of the first
5911 character of the match. Otherwise, <replaceable>endoption</replaceable>
5912 must be one, and the function returns the position of the character
5913 following the match.
5914 The <replaceable>flags</replaceable> parameter is an optional text
5915 string containing zero or more single-letter flags that change the
5916 function's behavior. Supported flags are described
5917 in <xref linkend="posix-embedded-options-table"/>.
5918 For a pattern containing parenthesized
5919 subexpressions, <replaceable>subexpr</replaceable> is an integer
5920 indicating which subexpression is of interest: the result identifies
5921 the position of the substring matching that subexpression.
5922 Subexpressions are numbered in the order of their leading parentheses.
5923 When <replaceable>subexpr</replaceable> is omitted or zero, the result
5924 identifies the position of the whole match regardless of
5925 parenthesized subexpressions.
5926 </para>
5928 <para>
5929 Some examples:
5930 <programlisting>
5931 regexp_instr('number of your street, town zip, FR', '[^,]+', 1, 2)
5932 <lineannotation>23</lineannotation>
5933 regexp_instr('ABCDEFGHI', '(c..)(...)', 1, 1, 0, 'i', 2)
5934 <lineannotation>6</lineannotation>
5935 </programlisting>
5936 </para>
5938 <para>
5939 The <function>regexp_like</function> function checks whether a match
5940 of a POSIX regular expression pattern occurs within a string,
5941 returning boolean true or false. It has the syntax
5942 <function>regexp_like</function>(<replaceable>string</replaceable>,
5943 <replaceable>pattern</replaceable>
5944 <optional>, <replaceable>flags</replaceable> </optional>).
5945 The <replaceable>flags</replaceable> parameter is an optional text
5946 string containing zero or more single-letter flags that change the
5947 function's behavior. Supported flags are described
5948 in <xref linkend="posix-embedded-options-table"/>.
5949 This function has the same results as the <literal>~</literal>
5950 operator if no flags are specified. If only the <literal>i</literal>
5951 flag is specified, it has the same results as
5952 the <literal>~*</literal> operator.
5953 </para>
5955 <para>
5956 Some examples:
5957 <programlisting>
5958 regexp_like('Hello World', 'world') <lineannotation>false</lineannotation>
5959 regexp_like('Hello World', 'world', 'i') <lineannotation>true</lineannotation>
5960 </programlisting>
5961 </para>
5963 <para>
5964 The <function>regexp_match</function> function returns a text array of
5965 matching substring(s) within the first match of a POSIX
5966 regular expression pattern to a string. It has the syntax
5967 <function>regexp_match</function>(<replaceable>string</replaceable>,
5968 <replaceable>pattern</replaceable> <optional>, <replaceable>flags</replaceable> </optional>).
5969 If there is no match, the result is <literal>NULL</literal>.
5970 If a match is found, and the <replaceable>pattern</replaceable> contains no
5971 parenthesized subexpressions, then the result is a single-element text
5972 array containing the substring matching the whole pattern.
5973 If a match is found, and the <replaceable>pattern</replaceable> contains
5974 parenthesized subexpressions, then the result is a text array
5975 whose <replaceable>n</replaceable>'th element is the substring matching
5976 the <replaceable>n</replaceable>'th parenthesized subexpression of
5977 the <replaceable>pattern</replaceable> (not counting <quote>non-capturing</quote>
5978 parentheses; see below for details).
5979 The <replaceable>flags</replaceable> parameter is an optional text string
5980 containing zero or more single-letter flags that change the function's
5981 behavior. Supported flags are described
5982 in <xref linkend="posix-embedded-options-table"/>.
5983 </para>
5985 <para>
5986 Some examples:
5987 <programlisting>
5988 SELECT regexp_match('foobarbequebaz', 'bar.*que');
5989 regexp_match
5990 --------------
5991 {barbeque}
5992 (1 row)
5994 SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
5995 regexp_match
5996 --------------
5997 {bar,beque}
5998 (1 row)
5999 </programlisting>
6000 </para>
6002 <tip>
6003 <para>
6004 In the common case where you just want the whole matching substring
6005 or <literal>NULL</literal> for no match, the best solution is to
6006 use <function>regexp_substr()</function>.
6007 However, <function>regexp_substr()</function> only exists
6008 in <productname>PostgreSQL</productname> version 15 and up. When
6009 working in older versions, you can extract the first element
6010 of <function>regexp_match()</function>'s result, for example:
6011 <programlisting>
6012 SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[1];
6013 regexp_match
6014 --------------
6015 barbeque
6016 (1 row)
6017 </programlisting>
6018 </para>
6019 </tip>
6021 <para>
6022 The <function>regexp_matches</function> function returns a set of text arrays
6023 of matching substring(s) within matches of a POSIX regular
6024 expression pattern to a string. It has the same syntax as
6025 <function>regexp_match</function>.
6026 This function returns no rows if there is no match, one row if there is
6027 a match and the <literal>g</literal> flag is not given, or <replaceable>N</replaceable>
6028 rows if there are <replaceable>N</replaceable> matches and the <literal>g</literal> flag
6029 is given. Each returned row is a text array containing the whole
6030 matched substring or the substrings matching parenthesized
6031 subexpressions of the <replaceable>pattern</replaceable>, just as described above
6032 for <function>regexp_match</function>.
6033 <function>regexp_matches</function> accepts all the flags shown
6034 in <xref linkend="posix-embedded-options-table"/>, plus
6035 the <literal>g</literal> flag which commands it to return all matches, not
6036 just the first one.
6037 </para>
6039 <para>
6040 Some examples:
6041 <programlisting>
6042 SELECT regexp_matches('foo', 'not there');
6043 regexp_matches
6044 ----------------
6045 (0 rows)
6047 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
6048 regexp_matches
6049 ----------------
6050 {bar,beque}
6051 {bazil,barf}
6052 (2 rows)
6053 </programlisting>
6054 </para>
6056 <tip>
6057 <para>
6058 In most cases <function>regexp_matches()</function> should be used with
6059 the <literal>g</literal> flag, since if you only want the first match, it's
6060 easier and more efficient to use <function>regexp_match()</function>.
6061 However, <function>regexp_match()</function> only exists
6062 in <productname>PostgreSQL</productname> version 10 and up. When working in older
6063 versions, a common trick is to place a <function>regexp_matches()</function>
6064 call in a sub-select, for example:
6065 <programlisting>
6066 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
6067 </programlisting>
6068 This produces a text array if there's a match, or <literal>NULL</literal> if
6069 not, the same as <function>regexp_match()</function> would do. Without the
6070 sub-select, this query would produce no output at all for table rows
6071 without a match, which is typically not the desired behavior.
6072 </para>
6073 </tip>
6075 <para>
6076 The <function>regexp_replace</function> function provides substitution of
6077 new text for substrings that match POSIX regular expression patterns.
6078 It has the syntax
6079 <function>regexp_replace</function>(<replaceable>source</replaceable>,
6080 <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>
6081 <optional>, <replaceable>start</replaceable>
6082 <optional>, <replaceable>N</replaceable>
6083 </optional></optional>
6084 <optional>, <replaceable>flags</replaceable> </optional>).
6085 (Notice that <replaceable>N</replaceable> cannot be specified
6086 unless <replaceable>start</replaceable> is,
6087 but <replaceable>flags</replaceable> can be given in any case.)
6088 The <replaceable>source</replaceable> string is returned unchanged if
6089 there is no match to the <replaceable>pattern</replaceable>. If there is a
6090 match, the <replaceable>source</replaceable> string is returned with the
6091 <replaceable>replacement</replaceable> string substituted for the matching
6092 substring. The <replaceable>replacement</replaceable> string can contain
6093 <literal>\</literal><replaceable>n</replaceable>, where <replaceable>n</replaceable> is 1
6094 through 9, to indicate that the source substring matching the
6095 <replaceable>n</replaceable>'th parenthesized subexpression of the pattern should be
6096 inserted, and it can contain <literal>\&amp;</literal> to indicate that the
6097 substring matching the entire pattern should be inserted. Write
6098 <literal>\\</literal> if you need to put a literal backslash in the replacement
6099 text.
6100 <replaceable>pattern</replaceable> is searched for
6101 in <replaceable>string</replaceable>, normally from the beginning of
6102 the string, but if the <replaceable>start</replaceable> parameter is
6103 provided then beginning from that character index.
6104 By default, only the first match of the pattern is replaced.
6105 If <replaceable>N</replaceable> is specified and is greater than zero,
6106 then the <replaceable>N</replaceable>'th match of the pattern
6107 is replaced.
6108 If the <literal>g</literal> flag is given, or
6109 if <replaceable>N</replaceable> is specified and is zero, then all
6110 matches at or after the <replaceable>start</replaceable> position are
6111 replaced. (The <literal>g</literal> flag is ignored
6112 when <replaceable>N</replaceable> is specified.)
6113 The <replaceable>flags</replaceable> parameter is an optional text
6114 string containing zero or more single-letter flags that change the
6115 function's behavior. Supported flags (though
6116 not <literal>g</literal>) are
6117 described in <xref linkend="posix-embedded-options-table"/>.
6118 </para>
6120 <para>
6121 Some examples:
6122 <programlisting>
6123 regexp_replace('foobarbaz', 'b..', 'X')
6124 <lineannotation>fooXbaz</lineannotation>
6125 regexp_replace('foobarbaz', 'b..', 'X', 'g')
6126 <lineannotation>fooXX</lineannotation>
6127 regexp_replace('foobarbaz', 'b(..)', 'X\1Y', 'g')
6128 <lineannotation>fooXarYXazY</lineannotation>
6129 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 0, 'i')
6130 <lineannotation>X PXstgrXSQL fXnctXXn</lineannotation>
6131 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 3, 'i')
6132 <lineannotation>A PostgrXSQL function</lineannotation>
6133 </programlisting>
6134 </para>
6136 <para>
6137 The <function>regexp_split_to_table</function> function splits a string using a POSIX
6138 regular expression pattern as a delimiter. It has the syntax
6139 <function>regexp_split_to_table</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
6140 <optional>, <replaceable>flags</replaceable> </optional>).
6141 If there is no match to the <replaceable>pattern</replaceable>, the function returns the
6142 <replaceable>string</replaceable>. If there is at least one match, for each match it returns
6143 the text from the end of the last match (or the beginning of the string)
6144 to the beginning of the match. When there are no more matches, it
6145 returns the text from the end of the last match to the end of the string.
6146 The <replaceable>flags</replaceable> parameter is an optional text string containing
6147 zero or more single-letter flags that change the function's behavior.
6148 <function>regexp_split_to_table</function> supports the flags described in
6149 <xref linkend="posix-embedded-options-table"/>.
6150 </para>
6152 <para>
6153 The <function>regexp_split_to_array</function> function behaves the same as
6154 <function>regexp_split_to_table</function>, except that <function>regexp_split_to_array</function>
6155 returns its result as an array of <type>text</type>. It has the syntax
6156 <function>regexp_split_to_array</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
6157 <optional>, <replaceable>flags</replaceable> </optional>).
6158 The parameters are the same as for <function>regexp_split_to_table</function>.
6159 </para>
6161 <para>
6162 Some examples:
6163 <programlisting>
6164 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo;
6166 -------
6168 quick
6169 brown
6171 jumps
6172 over
6174 lazy
6176 (9 rows)
6178 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+');
6179 regexp_split_to_array
6180 -----------------------------------------------
6181 {the,quick,brown,fox,jumps,over,the,lazy,dog}
6182 (1 row)
6184 SELECT foo FROM regexp_split_to_table('the quick brown fox', '\s*') AS foo;
6186 -----
6203 (16 rows)
6204 </programlisting>
6205 </para>
6207 <para>
6208 As the last example demonstrates, the regexp split functions ignore
6209 zero-length matches that occur at the start or end of the string
6210 or immediately after a previous match. This is contrary to the strict
6211 definition of regexp matching that is implemented by
6212 the other regexp functions, but is usually the most convenient behavior
6213 in practice. Other software systems such as Perl use similar definitions.
6214 </para>
6216 <para>
6217 The <function>regexp_substr</function> function returns the substring
6218 that matches a POSIX regular expression pattern,
6219 or <literal>NULL</literal> if there is no match. It has the syntax
6220 <function>regexp_substr</function>(<replaceable>string</replaceable>,
6221 <replaceable>pattern</replaceable>
6222 <optional>, <replaceable>start</replaceable>
6223 <optional>, <replaceable>N</replaceable>
6224 <optional>, <replaceable>flags</replaceable>
6225 <optional>, <replaceable>subexpr</replaceable>
6226 </optional></optional></optional></optional>).
6227 <replaceable>pattern</replaceable> is searched for
6228 in <replaceable>string</replaceable>, normally from the beginning of
6229 the string, but if the <replaceable>start</replaceable> parameter is
6230 provided then beginning from that character index.
6231 If <replaceable>N</replaceable> is specified
6232 then the <replaceable>N</replaceable>'th match of the pattern
6233 is returned, otherwise the first match is returned.
6234 The <replaceable>flags</replaceable> parameter is an optional text
6235 string containing zero or more single-letter flags that change the
6236 function's behavior. Supported flags are described
6237 in <xref linkend="posix-embedded-options-table"/>.
6238 For a pattern containing parenthesized
6239 subexpressions, <replaceable>subexpr</replaceable> is an integer
6240 indicating which subexpression is of interest: the result is the
6241 substring matching that subexpression.
6242 Subexpressions are numbered in the order of their leading parentheses.
6243 When <replaceable>subexpr</replaceable> is omitted or zero, the result
6244 is the whole match regardless of parenthesized subexpressions.
6245 </para>
6247 <para>
6248 Some examples:
6249 <programlisting>
6250 regexp_substr('number of your street, town zip, FR', '[^,]+', 1, 2)
6251 <lineannotation> town zip</lineannotation>
6252 regexp_substr('ABCDEFGHI', '(c..)(...)', 1, 1, 'i', 2)
6253 <lineannotation>FGH</lineannotation>
6254 </programlisting>
6255 </para>
6257 <!-- derived from the re_syntax.n man page -->
6259 <sect3 id="posix-syntax-details">
6260 <title>Regular Expression Details</title>
6262 <para>
6263 <productname>PostgreSQL</productname>'s regular expressions are implemented
6264 using a software package written by Henry Spencer. Much of
6265 the description of regular expressions below is copied verbatim from his
6266 manual.
6267 </para>
6269 <para>
6270 Regular expressions (<acronym>RE</acronym>s), as defined in
6271 <acronym>POSIX</acronym> 1003.2, come in two forms:
6272 <firstterm>extended</firstterm> <acronym>RE</acronym>s or <acronym>ERE</acronym>s
6273 (roughly those of <command>egrep</command>), and
6274 <firstterm>basic</firstterm> <acronym>RE</acronym>s or <acronym>BRE</acronym>s
6275 (roughly those of <command>ed</command>).
6276 <productname>PostgreSQL</productname> supports both forms, and
6277 also implements some extensions
6278 that are not in the POSIX standard, but have become widely used
6279 due to their availability in programming languages such as Perl and Tcl.
6280 <acronym>RE</acronym>s using these non-POSIX extensions are called
6281 <firstterm>advanced</firstterm> <acronym>RE</acronym>s or <acronym>ARE</acronym>s
6282 in this documentation. AREs are almost an exact superset of EREs,
6283 but BREs have several notational incompatibilities (as well as being
6284 much more limited).
6285 We first describe the ARE and ERE forms, noting features that apply
6286 only to AREs, and then describe how BREs differ.
6287 </para>
6289 <note>
6290 <para>
6291 <productname>PostgreSQL</productname> always initially presumes that a regular
6292 expression follows the ARE rules. However, the more limited ERE or
6293 BRE rules can be chosen by prepending an <firstterm>embedded option</firstterm>
6294 to the RE pattern, as described in <xref linkend="posix-metasyntax"/>.
6295 This can be useful for compatibility with applications that expect
6296 exactly the <acronym>POSIX</acronym> 1003.2 rules.
6297 </para>
6298 </note>
6300 <para>
6301 A regular expression is defined as one or more
6302 <firstterm>branches</firstterm>, separated by
6303 <literal>|</literal>. It matches anything that matches one of the
6304 branches.
6305 </para>
6307 <para>
6308 A branch is zero or more <firstterm>quantified atoms</firstterm> or
6309 <firstterm>constraints</firstterm>, concatenated.
6310 It matches a match for the first, followed by a match for the second, etc.;
6311 an empty branch matches the empty string.
6312 </para>
6314 <para>
6315 A quantified atom is an <firstterm>atom</firstterm> possibly followed
6316 by a single <firstterm>quantifier</firstterm>.
6317 Without a quantifier, it matches a match for the atom.
6318 With a quantifier, it can match some number of matches of the atom.
6319 An <firstterm>atom</firstterm> can be any of the possibilities
6320 shown in <xref linkend="posix-atoms-table"/>.
6321 The possible quantifiers and their meanings are shown in
6322 <xref linkend="posix-quantifiers-table"/>.
6323 </para>
6325 <para>
6326 A <firstterm>constraint</firstterm> matches an empty string, but matches only when
6327 specific conditions are met. A constraint can be used where an atom
6328 could be used, except it cannot be followed by a quantifier.
6329 The simple constraints are shown in
6330 <xref linkend="posix-constraints-table"/>;
6331 some more constraints are described later.
6332 </para>
6335 <table id="posix-atoms-table">
6336 <title>Regular Expression Atoms</title>
6338 <tgroup cols="2">
6339 <thead>
6340 <row>
6341 <entry>Atom</entry>
6342 <entry>Description</entry>
6343 </row>
6344 </thead>
6346 <tbody>
6347 <row>
6348 <entry> <literal>(</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6349 <entry> (where <replaceable>re</replaceable> is any regular expression)
6350 matches a match for
6351 <replaceable>re</replaceable>, with the match noted for possible reporting </entry>
6352 </row>
6354 <row>
6355 <entry> <literal>(?:</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6356 <entry> as above, but the match is not noted for reporting
6357 (a <quote>non-capturing</quote> set of parentheses)
6358 (AREs only) </entry>
6359 </row>
6361 <row>
6362 <entry> <literal>.</literal> </entry>
6363 <entry> matches any single character </entry>
6364 </row>
6366 <row>
6367 <entry> <literal>[</literal><replaceable>chars</replaceable><literal>]</literal> </entry>
6368 <entry> a <firstterm>bracket expression</firstterm>,
6369 matching any one of the <replaceable>chars</replaceable> (see
6370 <xref linkend="posix-bracket-expressions"/> for more detail) </entry>
6371 </row>
6373 <row>
6374 <entry> <literal>\</literal><replaceable>k</replaceable> </entry>
6375 <entry> (where <replaceable>k</replaceable> is a non-alphanumeric character)
6376 matches that character taken as an ordinary character,
6377 e.g., <literal>\\</literal> matches a backslash character </entry>
6378 </row>
6380 <row>
6381 <entry> <literal>\</literal><replaceable>c</replaceable> </entry>
6382 <entry> where <replaceable>c</replaceable> is alphanumeric
6383 (possibly followed by other characters)
6384 is an <firstterm>escape</firstterm>, see <xref linkend="posix-escape-sequences"/>
6385 (AREs only; in EREs and BREs, this matches <replaceable>c</replaceable>) </entry>
6386 </row>
6388 <row>
6389 <entry> <literal>{</literal> </entry>
6390 <entry> when followed by a character other than a digit,
6391 matches the left-brace character <literal>{</literal>;
6392 when followed by a digit, it is the beginning of a
6393 <replaceable>bound</replaceable> (see below) </entry>
6394 </row>
6396 <row>
6397 <entry> <replaceable>x</replaceable> </entry>
6398 <entry> where <replaceable>x</replaceable> is a single character with no other
6399 significance, matches that character </entry>
6400 </row>
6401 </tbody>
6402 </tgroup>
6403 </table>
6405 <para>
6406 An RE cannot end with a backslash (<literal>\</literal>).
6407 </para>
6409 <note>
6410 <para>
6411 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
6412 any backslashes you write in literal string constants will need to be
6413 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
6414 </para>
6415 </note>
6417 <table id="posix-quantifiers-table">
6418 <title>Regular Expression Quantifiers</title>
6420 <tgroup cols="2">
6421 <thead>
6422 <row>
6423 <entry>Quantifier</entry>
6424 <entry>Matches</entry>
6425 </row>
6426 </thead>
6428 <tbody>
6429 <row>
6430 <entry> <literal>*</literal> </entry>
6431 <entry> a sequence of 0 or more matches of the atom </entry>
6432 </row>
6434 <row>
6435 <entry> <literal>+</literal> </entry>
6436 <entry> a sequence of 1 or more matches of the atom </entry>
6437 </row>
6439 <row>
6440 <entry> <literal>?</literal> </entry>
6441 <entry> a sequence of 0 or 1 matches of the atom </entry>
6442 </row>
6444 <row>
6445 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6446 <entry> a sequence of exactly <replaceable>m</replaceable> matches of the atom </entry>
6447 </row>
6449 <row>
6450 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6451 <entry> a sequence of <replaceable>m</replaceable> or more matches of the atom </entry>
6452 </row>
6454 <row>
6455 <entry>
6456 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6457 <entry> a sequence of <replaceable>m</replaceable> through <replaceable>n</replaceable>
6458 (inclusive) matches of the atom; <replaceable>m</replaceable> cannot exceed
6459 <replaceable>n</replaceable> </entry>
6460 </row>
6462 <row>
6463 <entry> <literal>*?</literal> </entry>
6464 <entry> non-greedy version of <literal>*</literal> </entry>
6465 </row>
6467 <row>
6468 <entry> <literal>+?</literal> </entry>
6469 <entry> non-greedy version of <literal>+</literal> </entry>
6470 </row>
6472 <row>
6473 <entry> <literal>??</literal> </entry>
6474 <entry> non-greedy version of <literal>?</literal> </entry>
6475 </row>
6477 <row>
6478 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}?</literal> </entry>
6479 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6480 </row>
6482 <row>
6483 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}?</literal> </entry>
6484 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6485 </row>
6487 <row>
6488 <entry>
6489 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal> </entry>
6490 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6491 </row>
6492 </tbody>
6493 </tgroup>
6494 </table>
6496 <para>
6497 The forms using <literal>{</literal><replaceable>...</replaceable><literal>}</literal>
6498 are known as <firstterm>bounds</firstterm>.
6499 The numbers <replaceable>m</replaceable> and <replaceable>n</replaceable> within a bound are
6500 unsigned decimal integers with permissible values from 0 to 255 inclusive.
6501 </para>
6503 <para>
6504 <firstterm>Non-greedy</firstterm> quantifiers (available in AREs only) match the
6505 same possibilities as their corresponding normal (<firstterm>greedy</firstterm>)
6506 counterparts, but prefer the smallest number rather than the largest
6507 number of matches.
6508 See <xref linkend="posix-matching-rules"/> for more detail.
6509 </para>
6511 <note>
6512 <para>
6513 A quantifier cannot immediately follow another quantifier, e.g.,
6514 <literal>**</literal> is invalid.
6515 A quantifier cannot
6516 begin an expression or subexpression or follow
6517 <literal>^</literal> or <literal>|</literal>.
6518 </para>
6519 </note>
6521 <table id="posix-constraints-table">
6522 <title>Regular Expression Constraints</title>
6524 <tgroup cols="2">
6525 <thead>
6526 <row>
6527 <entry>Constraint</entry>
6528 <entry>Description</entry>
6529 </row>
6530 </thead>
6532 <tbody>
6533 <row>
6534 <entry> <literal>^</literal> </entry>
6535 <entry> matches at the beginning of the string </entry>
6536 </row>
6538 <row>
6539 <entry> <literal>$</literal> </entry>
6540 <entry> matches at the end of the string </entry>
6541 </row>
6543 <row>
6544 <entry> <literal>(?=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6545 <entry> <firstterm>positive lookahead</firstterm> matches at any point
6546 where a substring matching <replaceable>re</replaceable> begins
6547 (AREs only) </entry>
6548 </row>
6550 <row>
6551 <entry> <literal>(?!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6552 <entry> <firstterm>negative lookahead</firstterm> matches at any point
6553 where no substring matching <replaceable>re</replaceable> begins
6554 (AREs only) </entry>
6555 </row>
6557 <row>
6558 <entry> <literal>(?&lt;=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6559 <entry> <firstterm>positive lookbehind</firstterm> matches at any point
6560 where a substring matching <replaceable>re</replaceable> ends
6561 (AREs only) </entry>
6562 </row>
6564 <row>
6565 <entry> <literal>(?&lt;!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6566 <entry> <firstterm>negative lookbehind</firstterm> matches at any point
6567 where no substring matching <replaceable>re</replaceable> ends
6568 (AREs only) </entry>
6569 </row>
6570 </tbody>
6571 </tgroup>
6572 </table>
6574 <para>
6575 Lookahead and lookbehind constraints cannot contain <firstterm>back
6576 references</firstterm> (see <xref linkend="posix-escape-sequences"/>),
6577 and all parentheses within them are considered non-capturing.
6578 </para>
6579 </sect3>
6581 <sect3 id="posix-bracket-expressions">
6582 <title>Bracket Expressions</title>
6584 <para>
6585 A <firstterm>bracket expression</firstterm> is a list of
6586 characters enclosed in <literal>[]</literal>. It normally matches
6587 any single character from the list (but see below). If the list
6588 begins with <literal>^</literal>, it matches any single character
6589 <emphasis>not</emphasis> from the rest of the list.
6590 If two characters
6591 in the list are separated by <literal>-</literal>, this is
6592 shorthand for the full range of characters between those two
6593 (inclusive) in the collating sequence,
6594 e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
6595 any decimal digit. It is illegal for two ranges to share an
6596 endpoint, e.g., <literal>a-c-e</literal>. Ranges are very
6597 collating-sequence-dependent, so portable programs should avoid
6598 relying on them.
6599 </para>
6601 <para>
6602 To include a literal <literal>]</literal> in the list, make it the
6603 first character (after <literal>^</literal>, if that is used). To
6604 include a literal <literal>-</literal>, make it the first or last
6605 character, or the second endpoint of a range. To use a literal
6606 <literal>-</literal> as the first endpoint of a range, enclose it
6607 in <literal>[.</literal> and <literal>.]</literal> to make it a
6608 collating element (see below). With the exception of these characters,
6609 some combinations using <literal>[</literal>
6610 (see next paragraphs), and escapes (AREs only), all other special
6611 characters lose their special significance within a bracket expression.
6612 In particular, <literal>\</literal> is not special when following
6613 ERE or BRE rules, though it is special (as introducing an escape)
6614 in AREs.
6615 </para>
6617 <para>
6618 Within a bracket expression, a collating element (a character, a
6619 multiple-character sequence that collates as if it were a single
6620 character, or a collating-sequence name for either) enclosed in
6621 <literal>[.</literal> and <literal>.]</literal> stands for the
6622 sequence of characters of that collating element. The sequence is
6623 treated as a single element of the bracket expression's list. This
6624 allows a bracket
6625 expression containing a multiple-character collating element to
6626 match more than one character, e.g., if the collating sequence
6627 includes a <literal>ch</literal> collating element, then the RE
6628 <literal>[[.ch.]]*c</literal> matches the first five characters of
6629 <literal>chchcc</literal>.
6630 </para>
6632 <note>
6633 <para>
6634 <productname>PostgreSQL</productname> currently does not support multi-character collating
6635 elements. This information describes possible future behavior.
6636 </para>
6637 </note>
6639 <para>
6640 Within a bracket expression, a collating element enclosed in
6641 <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
6642 class</firstterm>, standing for the sequences of characters of all collating
6643 elements equivalent to that one, including itself. (If there are
6644 no other equivalent collating elements, the treatment is as if the
6645 enclosing delimiters were <literal>[.</literal> and
6646 <literal>.]</literal>.) For example, if <literal>o</literal> and
6647 <literal>^</literal> are the members of an equivalence class, then
6648 <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
6649 <literal>[o^]</literal> are all synonymous. An equivalence class
6650 cannot be an endpoint of a range.
6651 </para>
6653 <para>
6654 Within a bracket expression, the name of a character class
6655 enclosed in <literal>[:</literal> and <literal>:]</literal> stands
6656 for the list of all characters belonging to that class. A character
6657 class cannot be used as an endpoint of a range.
6658 The <acronym>POSIX</acronym> standard defines these character class
6659 names:
6660 <literal>alnum</literal> (letters and numeric digits),
6661 <literal>alpha</literal> (letters),
6662 <literal>blank</literal> (space and tab),
6663 <literal>cntrl</literal> (control characters),
6664 <literal>digit</literal> (numeric digits),
6665 <literal>graph</literal> (printable characters except space),
6666 <literal>lower</literal> (lower-case letters),
6667 <literal>print</literal> (printable characters including space),
6668 <literal>punct</literal> (punctuation),
6669 <literal>space</literal> (any white space),
6670 <literal>upper</literal> (upper-case letters),
6671 and <literal>xdigit</literal> (hexadecimal digits).
6672 The behavior of these standard character classes is generally
6673 consistent across platforms for characters in the 7-bit ASCII set.
6674 Whether a given non-ASCII character is considered to belong to one
6675 of these classes depends on the <firstterm>collation</firstterm>
6676 that is used for the regular-expression function or operator
6677 (see <xref linkend="collation"/>), or by default on the
6678 database's <envar>LC_CTYPE</envar> locale setting (see
6679 <xref linkend="locale"/>). The classification of non-ASCII
6680 characters can vary across platforms even in similarly-named
6681 locales. (But the <literal>C</literal> locale never considers any
6682 non-ASCII characters to belong to any of these classes.)
6683 In addition to these standard character
6684 classes, <productname>PostgreSQL</productname> defines
6685 the <literal>word</literal> character class, which is the same as
6686 <literal>alnum</literal> plus the underscore (<literal>_</literal>)
6687 character, and
6688 the <literal>ascii</literal> character class, which contains exactly
6689 the 7-bit ASCII set.
6690 </para>
6692 <para>
6693 There are two special cases of bracket expressions: the bracket
6694 expressions <literal>[[:&lt;:]]</literal> and
6695 <literal>[[:&gt;:]]</literal> are constraints,
6696 matching empty strings at the beginning
6697 and end of a word respectively. A word is defined as a sequence
6698 of word characters that is neither preceded nor followed by word
6699 characters. A word character is any character belonging to the
6700 <literal>word</literal> character class, that is, any letter, digit,
6701 or underscore. This is an extension, compatible with but not
6702 specified by <acronym>POSIX</acronym> 1003.2, and should be used with
6703 caution in software intended to be portable to other systems.
6704 The constraint escapes described below are usually preferable; they
6705 are no more standard, but are easier to type.
6706 </para>
6707 </sect3>
6709 <sect3 id="posix-escape-sequences">
6710 <title>Regular Expression Escapes</title>
6712 <para>
6713 <firstterm>Escapes</firstterm> are special sequences beginning with <literal>\</literal>
6714 followed by an alphanumeric character. Escapes come in several varieties:
6715 character entry, class shorthands, constraint escapes, and back references.
6716 A <literal>\</literal> followed by an alphanumeric character but not constituting
6717 a valid escape is illegal in AREs.
6718 In EREs, there are no escapes: outside a bracket expression,
6719 a <literal>\</literal> followed by an alphanumeric character merely stands for
6720 that character as an ordinary character, and inside a bracket expression,
6721 <literal>\</literal> is an ordinary character.
6722 (The latter is the one actual incompatibility between EREs and AREs.)
6723 </para>
6725 <para>
6726 <firstterm>Character-entry escapes</firstterm> exist to make it easier to specify
6727 non-printing and other inconvenient characters in REs. They are
6728 shown in <xref linkend="posix-character-entry-escapes-table"/>.
6729 </para>
6731 <para>
6732 <firstterm>Class-shorthand escapes</firstterm> provide shorthands for certain
6733 commonly-used character classes. They are
6734 shown in <xref linkend="posix-class-shorthand-escapes-table"/>.
6735 </para>
6737 <para>
6738 A <firstterm>constraint escape</firstterm> is a constraint,
6739 matching the empty string if specific conditions are met,
6740 written as an escape. They are
6741 shown in <xref linkend="posix-constraint-escapes-table"/>.
6742 </para>
6744 <para>
6745 A <firstterm>back reference</firstterm> (<literal>\</literal><replaceable>n</replaceable>) matches the
6746 same string matched by the previous parenthesized subexpression specified
6747 by the number <replaceable>n</replaceable>
6748 (see <xref linkend="posix-constraint-backref-table"/>). For example,
6749 <literal>([bc])\1</literal> matches <literal>bb</literal> or <literal>cc</literal>
6750 but not <literal>bc</literal> or <literal>cb</literal>.
6751 The subexpression must entirely precede the back reference in the RE.
6752 Subexpressions are numbered in the order of their leading parentheses.
6753 Non-capturing parentheses do not define subexpressions.
6754 The back reference considers only the string characters matched by the
6755 referenced subexpression, not any constraints contained in it. For
6756 example, <literal>(^\d)\1</literal> will match <literal>22</literal>.
6757 </para>
6759 <table id="posix-character-entry-escapes-table">
6760 <title>Regular Expression Character-Entry Escapes</title>
6762 <tgroup cols="2">
6763 <thead>
6764 <row>
6765 <entry>Escape</entry>
6766 <entry>Description</entry>
6767 </row>
6768 </thead>
6770 <tbody>
6771 <row>
6772 <entry> <literal>\a</literal> </entry>
6773 <entry> alert (bell) character, as in C </entry>
6774 </row>
6776 <row>
6777 <entry> <literal>\b</literal> </entry>
6778 <entry> backspace, as in C </entry>
6779 </row>
6781 <row>
6782 <entry> <literal>\B</literal> </entry>
6783 <entry> synonym for backslash (<literal>\</literal>) to help reduce the need for backslash
6784 doubling </entry>
6785 </row>
6787 <row>
6788 <entry> <literal>\c</literal><replaceable>X</replaceable> </entry>
6789 <entry> (where <replaceable>X</replaceable> is any character) the character whose
6790 low-order 5 bits are the same as those of
6791 <replaceable>X</replaceable>, and whose other bits are all zero </entry>
6792 </row>
6794 <row>
6795 <entry> <literal>\e</literal> </entry>
6796 <entry> the character whose collating-sequence name
6797 is <literal>ESC</literal>,
6798 or failing that, the character with octal value <literal>033</literal> </entry>
6799 </row>
6801 <row>
6802 <entry> <literal>\f</literal> </entry>
6803 <entry> form feed, as in C </entry>
6804 </row>
6806 <row>
6807 <entry> <literal>\n</literal> </entry>
6808 <entry> newline, as in C </entry>
6809 </row>
6811 <row>
6812 <entry> <literal>\r</literal> </entry>
6813 <entry> carriage return, as in C </entry>
6814 </row>
6816 <row>
6817 <entry> <literal>\t</literal> </entry>
6818 <entry> horizontal tab, as in C </entry>
6819 </row>
6821 <row>
6822 <entry> <literal>\u</literal><replaceable>wxyz</replaceable> </entry>
6823 <entry> (where <replaceable>wxyz</replaceable> is exactly four hexadecimal digits)
6824 the character whose hexadecimal value is
6825 <literal>0x</literal><replaceable>wxyz</replaceable>
6826 </entry>
6827 </row>
6829 <row>
6830 <entry> <literal>\U</literal><replaceable>stuvwxyz</replaceable> </entry>
6831 <entry> (where <replaceable>stuvwxyz</replaceable> is exactly eight hexadecimal
6832 digits)
6833 the character whose hexadecimal value is
6834 <literal>0x</literal><replaceable>stuvwxyz</replaceable>
6835 </entry>
6836 </row>
6838 <row>
6839 <entry> <literal>\v</literal> </entry>
6840 <entry> vertical tab, as in C </entry>
6841 </row>
6843 <row>
6844 <entry> <literal>\x</literal><replaceable>hhh</replaceable> </entry>
6845 <entry> (where <replaceable>hhh</replaceable> is any sequence of hexadecimal
6846 digits)
6847 the character whose hexadecimal value is
6848 <literal>0x</literal><replaceable>hhh</replaceable>
6849 (a single character no matter how many hexadecimal digits are used)
6850 </entry>
6851 </row>
6853 <row>
6854 <entry> <literal>\0</literal> </entry>
6855 <entry> the character whose value is <literal>0</literal> (the null byte)</entry>
6856 </row>
6858 <row>
6859 <entry> <literal>\</literal><replaceable>xy</replaceable> </entry>
6860 <entry> (where <replaceable>xy</replaceable> is exactly two octal digits,
6861 and is not a <firstterm>back reference</firstterm>)
6862 the character whose octal value is
6863 <literal>0</literal><replaceable>xy</replaceable> </entry>
6864 </row>
6866 <row>
6867 <entry> <literal>\</literal><replaceable>xyz</replaceable> </entry>
6868 <entry> (where <replaceable>xyz</replaceable> is exactly three octal digits,
6869 and is not a <firstterm>back reference</firstterm>)
6870 the character whose octal value is
6871 <literal>0</literal><replaceable>xyz</replaceable> </entry>
6872 </row>
6873 </tbody>
6874 </tgroup>
6875 </table>
6877 <para>
6878 Hexadecimal digits are <literal>0</literal>-<literal>9</literal>,
6879 <literal>a</literal>-<literal>f</literal>, and <literal>A</literal>-<literal>F</literal>.
6880 Octal digits are <literal>0</literal>-<literal>7</literal>.
6881 </para>
6883 <para>
6884 Numeric character-entry escapes specifying values outside the ASCII range
6885 (0&ndash;127) have meanings dependent on the database encoding. When the
6886 encoding is UTF-8, escape values are equivalent to Unicode code points,
6887 for example <literal>\u1234</literal> means the character <literal>U+1234</literal>.
6888 For other multibyte encodings, character-entry escapes usually just
6889 specify the concatenation of the byte values for the character. If the
6890 escape value does not correspond to any legal character in the database
6891 encoding, no error will be raised, but it will never match any data.
6892 </para>
6894 <para>
6895 The character-entry escapes are always taken as ordinary characters.
6896 For example, <literal>\135</literal> is <literal>]</literal> in ASCII, but
6897 <literal>\135</literal> does not terminate a bracket expression.
6898 </para>
6900 <table id="posix-class-shorthand-escapes-table">
6901 <title>Regular Expression Class-Shorthand Escapes</title>
6903 <tgroup cols="2">
6904 <thead>
6905 <row>
6906 <entry>Escape</entry>
6907 <entry>Description</entry>
6908 </row>
6909 </thead>
6911 <tbody>
6912 <row>
6913 <entry> <literal>\d</literal> </entry>
6914 <entry> matches any digit, like
6915 <literal>[[:digit:]]</literal> </entry>
6916 </row>
6918 <row>
6919 <entry> <literal>\s</literal> </entry>
6920 <entry> matches any whitespace character, like
6921 <literal>[[:space:]]</literal> </entry>
6922 </row>
6924 <row>
6925 <entry> <literal>\w</literal> </entry>
6926 <entry> matches any word character, like
6927 <literal>[[:word:]]</literal> </entry>
6928 </row>
6930 <row>
6931 <entry> <literal>\D</literal> </entry>
6932 <entry> matches any non-digit, like
6933 <literal>[^[:digit:]]</literal> </entry>
6934 </row>
6936 <row>
6937 <entry> <literal>\S</literal> </entry>
6938 <entry> matches any non-whitespace character, like
6939 <literal>[^[:space:]]</literal> </entry>
6940 </row>
6942 <row>
6943 <entry> <literal>\W</literal> </entry>
6944 <entry> matches any non-word character, like
6945 <literal>[^[:word:]]</literal> </entry>
6946 </row>
6947 </tbody>
6948 </tgroup>
6949 </table>
6951 <para>
6952 The class-shorthand escapes also work within bracket expressions,
6953 although the definitions shown above are not quite syntactically
6954 valid in that context.
6955 For example, <literal>[a-c\d]</literal> is equivalent to
6956 <literal>[a-c[:digit:]]</literal>.
6957 </para>
6959 <table id="posix-constraint-escapes-table">
6960 <title>Regular Expression Constraint Escapes</title>
6962 <tgroup cols="2">
6963 <thead>
6964 <row>
6965 <entry>Escape</entry>
6966 <entry>Description</entry>
6967 </row>
6968 </thead>
6970 <tbody>
6971 <row>
6972 <entry> <literal>\A</literal> </entry>
6973 <entry> matches only at the beginning of the string
6974 (see <xref linkend="posix-matching-rules"/> for how this differs from
6975 <literal>^</literal>) </entry>
6976 </row>
6978 <row>
6979 <entry> <literal>\m</literal> </entry>
6980 <entry> matches only at the beginning of a word </entry>
6981 </row>
6983 <row>
6984 <entry> <literal>\M</literal> </entry>
6985 <entry> matches only at the end of a word </entry>
6986 </row>
6988 <row>
6989 <entry> <literal>\y</literal> </entry>
6990 <entry> matches only at the beginning or end of a word </entry>
6991 </row>
6993 <row>
6994 <entry> <literal>\Y</literal> </entry>
6995 <entry> matches only at a point that is not the beginning or end of a
6996 word </entry>
6997 </row>
6999 <row>
7000 <entry> <literal>\Z</literal> </entry>
7001 <entry> matches only at the end of the string
7002 (see <xref linkend="posix-matching-rules"/> for how this differs from
7003 <literal>$</literal>) </entry>
7004 </row>
7005 </tbody>
7006 </tgroup>
7007 </table>
7009 <para>
7010 A word is defined as in the specification of
7011 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal> above.
7012 Constraint escapes are illegal within bracket expressions.
7013 </para>
7015 <table id="posix-constraint-backref-table">
7016 <title>Regular Expression Back References</title>
7018 <tgroup cols="2">
7019 <thead>
7020 <row>
7021 <entry>Escape</entry>
7022 <entry>Description</entry>
7023 </row>
7024 </thead>
7026 <tbody>
7027 <row>
7028 <entry> <literal>\</literal><replaceable>m</replaceable> </entry>
7029 <entry> (where <replaceable>m</replaceable> is a nonzero digit)
7030 a back reference to the <replaceable>m</replaceable>'th subexpression </entry>
7031 </row>
7033 <row>
7034 <entry> <literal>\</literal><replaceable>mnn</replaceable> </entry>
7035 <entry> (where <replaceable>m</replaceable> is a nonzero digit, and
7036 <replaceable>nn</replaceable> is some more digits, and the decimal value
7037 <replaceable>mnn</replaceable> is not greater than the number of closing capturing
7038 parentheses seen so far)
7039 a back reference to the <replaceable>mnn</replaceable>'th subexpression </entry>
7040 </row>
7041 </tbody>
7042 </tgroup>
7043 </table>
7045 <note>
7046 <para>
7047 There is an inherent ambiguity between octal character-entry
7048 escapes and back references, which is resolved by the following heuristics,
7049 as hinted at above.
7050 A leading zero always indicates an octal escape.
7051 A single non-zero digit, not followed by another digit,
7052 is always taken as a back reference.
7053 A multi-digit sequence not starting with a zero is taken as a back
7054 reference if it comes after a suitable subexpression
7055 (i.e., the number is in the legal range for a back reference),
7056 and otherwise is taken as octal.
7057 </para>
7058 </note>
7059 </sect3>
7061 <sect3 id="posix-metasyntax">
7062 <title>Regular Expression Metasyntax</title>
7064 <para>
7065 In addition to the main syntax described above, there are some special
7066 forms and miscellaneous syntactic facilities available.
7067 </para>
7069 <para>
7070 An RE can begin with one of two special <firstterm>director</firstterm> prefixes.
7071 If an RE begins with <literal>***:</literal>,
7072 the rest of the RE is taken as an ARE. (This normally has no effect in
7073 <productname>PostgreSQL</productname>, since REs are assumed to be AREs;
7074 but it does have an effect if ERE or BRE mode had been specified by
7075 the <replaceable>flags</replaceable> parameter to a regex function.)
7076 If an RE begins with <literal>***=</literal>,
7077 the rest of the RE is taken to be a literal string,
7078 with all characters considered ordinary characters.
7079 </para>
7081 <para>
7082 An ARE can begin with <firstterm>embedded options</firstterm>:
7083 a sequence <literal>(?</literal><replaceable>xyz</replaceable><literal>)</literal>
7084 (where <replaceable>xyz</replaceable> is one or more alphabetic characters)
7085 specifies options affecting the rest of the RE.
7086 These options override any previously determined options &mdash;
7087 in particular, they can override the case-sensitivity behavior implied by
7088 a regex operator, or the <replaceable>flags</replaceable> parameter to a regex
7089 function.
7090 The available option letters are
7091 shown in <xref linkend="posix-embedded-options-table"/>.
7092 Note that these same option letters are used in the <replaceable>flags</replaceable>
7093 parameters of regex functions.
7094 </para>
7096 <table id="posix-embedded-options-table">
7097 <title>ARE Embedded-Option Letters</title>
7099 <tgroup cols="2">
7100 <thead>
7101 <row>
7102 <entry>Option</entry>
7103 <entry>Description</entry>
7104 </row>
7105 </thead>
7107 <tbody>
7108 <row>
7109 <entry> <literal>b</literal> </entry>
7110 <entry> rest of RE is a BRE </entry>
7111 </row>
7113 <row>
7114 <entry> <literal>c</literal> </entry>
7115 <entry> case-sensitive matching (overrides operator type) </entry>
7116 </row>
7118 <row>
7119 <entry> <literal>e</literal> </entry>
7120 <entry> rest of RE is an ERE </entry>
7121 </row>
7123 <row>
7124 <entry> <literal>i</literal> </entry>
7125 <entry> case-insensitive matching (see
7126 <xref linkend="posix-matching-rules"/>) (overrides operator type) </entry>
7127 </row>
7129 <row>
7130 <entry> <literal>m</literal> </entry>
7131 <entry> historical synonym for <literal>n</literal> </entry>
7132 </row>
7134 <row>
7135 <entry> <literal>n</literal> </entry>
7136 <entry> newline-sensitive matching (see
7137 <xref linkend="posix-matching-rules"/>) </entry>
7138 </row>
7140 <row>
7141 <entry> <literal>p</literal> </entry>
7142 <entry> partial newline-sensitive matching (see
7143 <xref linkend="posix-matching-rules"/>) </entry>
7144 </row>
7146 <row>
7147 <entry> <literal>q</literal> </entry>
7148 <entry> rest of RE is a literal (<quote>quoted</quote>) string, all ordinary
7149 characters </entry>
7150 </row>
7152 <row>
7153 <entry> <literal>s</literal> </entry>
7154 <entry> non-newline-sensitive matching (default) </entry>
7155 </row>
7157 <row>
7158 <entry> <literal>t</literal> </entry>
7159 <entry> tight syntax (default; see below) </entry>
7160 </row>
7162 <row>
7163 <entry> <literal>w</literal> </entry>
7164 <entry> inverse partial newline-sensitive (<quote>weird</quote>) matching
7165 (see <xref linkend="posix-matching-rules"/>) </entry>
7166 </row>
7168 <row>
7169 <entry> <literal>x</literal> </entry>
7170 <entry> expanded syntax (see below) </entry>
7171 </row>
7172 </tbody>
7173 </tgroup>
7174 </table>
7176 <para>
7177 Embedded options take effect at the <literal>)</literal> terminating the sequence.
7178 They can appear only at the start of an ARE (after the
7179 <literal>***:</literal> director if any).
7180 </para>
7182 <para>
7183 In addition to the usual (<firstterm>tight</firstterm>) RE syntax, in which all
7184 characters are significant, there is an <firstterm>expanded</firstterm> syntax,
7185 available by specifying the embedded <literal>x</literal> option.
7186 In the expanded syntax,
7187 white-space characters in the RE are ignored, as are
7188 all characters between a <literal>#</literal>
7189 and the following newline (or the end of the RE). This
7190 permits paragraphing and commenting a complex RE.
7191 There are three exceptions to that basic rule:
7193 <itemizedlist>
7194 <listitem>
7195 <para>
7196 a white-space character or <literal>#</literal> preceded by <literal>\</literal> is
7197 retained
7198 </para>
7199 </listitem>
7200 <listitem>
7201 <para>
7202 white space or <literal>#</literal> within a bracket expression is retained
7203 </para>
7204 </listitem>
7205 <listitem>
7206 <para>
7207 white space and comments cannot appear within multi-character symbols,
7208 such as <literal>(?:</literal>
7209 </para>
7210 </listitem>
7211 </itemizedlist>
7213 For this purpose, white-space characters are blank, tab, newline, and
7214 any character that belongs to the <replaceable>space</replaceable> character class.
7215 </para>
7217 <para>
7218 Finally, in an ARE, outside bracket expressions, the sequence
7219 <literal>(?#</literal><replaceable>ttt</replaceable><literal>)</literal>
7220 (where <replaceable>ttt</replaceable> is any text not containing a <literal>)</literal>)
7221 is a comment, completely ignored.
7222 Again, this is not allowed between the characters of
7223 multi-character symbols, like <literal>(?:</literal>.
7224 Such comments are more a historical artifact than a useful facility,
7225 and their use is deprecated; use the expanded syntax instead.
7226 </para>
7228 <para>
7229 <emphasis>None</emphasis> of these metasyntax extensions is available if
7230 an initial <literal>***=</literal> director
7231 has specified that the user's input be treated as a literal string
7232 rather than as an RE.
7233 </para>
7234 </sect3>
7236 <sect3 id="posix-matching-rules">
7237 <title>Regular Expression Matching Rules</title>
7239 <para>
7240 In the event that an RE could match more than one substring of a given
7241 string, the RE matches the one starting earliest in the string.
7242 If the RE could match more than one substring starting at that point,
7243 either the longest possible match or the shortest possible match will
7244 be taken, depending on whether the RE is <firstterm>greedy</firstterm> or
7245 <firstterm>non-greedy</firstterm>.
7246 </para>
7248 <para>
7249 Whether an RE is greedy or not is determined by the following rules:
7250 <itemizedlist>
7251 <listitem>
7252 <para>
7253 Most atoms, and all constraints, have no greediness attribute (because
7254 they cannot match variable amounts of text anyway).
7255 </para>
7256 </listitem>
7257 <listitem>
7258 <para>
7259 Adding parentheses around an RE does not change its greediness.
7260 </para>
7261 </listitem>
7262 <listitem>
7263 <para>
7264 A quantified atom with a fixed-repetition quantifier
7265 (<literal>{</literal><replaceable>m</replaceable><literal>}</literal>
7267 <literal>{</literal><replaceable>m</replaceable><literal>}?</literal>)
7268 has the same greediness (possibly none) as the atom itself.
7269 </para>
7270 </listitem>
7271 <listitem>
7272 <para>
7273 A quantified atom with other normal quantifiers (including
7274 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
7275 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7276 is greedy (prefers longest match).
7277 </para>
7278 </listitem>
7279 <listitem>
7280 <para>
7281 A quantified atom with a non-greedy quantifier (including
7282 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal>
7283 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7284 is non-greedy (prefers shortest match).
7285 </para>
7286 </listitem>
7287 <listitem>
7288 <para>
7289 A branch &mdash; that is, an RE that has no top-level
7290 <literal>|</literal> operator &mdash; has the same greediness as the first
7291 quantified atom in it that has a greediness attribute.
7292 </para>
7293 </listitem>
7294 <listitem>
7295 <para>
7296 An RE consisting of two or more branches connected by the
7297 <literal>|</literal> operator is always greedy.
7298 </para>
7299 </listitem>
7300 </itemizedlist>
7301 </para>
7303 <para>
7304 The above rules associate greediness attributes not only with individual
7305 quantified atoms, but with branches and entire REs that contain quantified
7306 atoms. What that means is that the matching is done in such a way that
7307 the branch, or whole RE, matches the longest or shortest possible
7308 substring <emphasis>as a whole</emphasis>. Once the length of the entire match
7309 is determined, the part of it that matches any particular subexpression
7310 is determined on the basis of the greediness attribute of that
7311 subexpression, with subexpressions starting earlier in the RE taking
7312 priority over ones starting later.
7313 </para>
7315 <para>
7316 An example of what this means:
7317 <screen>
7318 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
7319 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
7320 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
7321 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7322 </screen>
7323 In the first case, the RE as a whole is greedy because <literal>Y*</literal>
7324 is greedy. It can match beginning at the <literal>Y</literal>, and it matches
7325 the longest possible string starting there, i.e., <literal>Y123</literal>.
7326 The output is the parenthesized part of that, or <literal>123</literal>.
7327 In the second case, the RE as a whole is non-greedy because <literal>Y*?</literal>
7328 is non-greedy. It can match beginning at the <literal>Y</literal>, and it matches
7329 the shortest possible string starting there, i.e., <literal>Y1</literal>.
7330 The subexpression <literal>[0-9]{1,3}</literal> is greedy but it cannot change
7331 the decision as to the overall match length; so it is forced to match
7332 just <literal>1</literal>.
7333 </para>
7335 <para>
7336 In short, when an RE contains both greedy and non-greedy subexpressions,
7337 the total match length is either as long as possible or as short as
7338 possible, according to the attribute assigned to the whole RE. The
7339 attributes assigned to the subexpressions only affect how much of that
7340 match they are allowed to <quote>eat</quote> relative to each other.
7341 </para>
7343 <para>
7344 The quantifiers <literal>{1,1}</literal> and <literal>{1,1}?</literal>
7345 can be used to force greediness or non-greediness, respectively,
7346 on a subexpression or a whole RE.
7347 This is useful when you need the whole RE to have a greediness attribute
7348 different from what's deduced from its elements. As an example,
7349 suppose that we are trying to separate a string containing some digits
7350 into the digits and the parts before and after them. We might try to
7351 do that like this:
7352 <screen>
7353 SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
7354 <lineannotation>Result: </lineannotation><computeroutput>{abc0123,4,xyz}</computeroutput>
7355 </screen>
7356 That didn't work: the first <literal>.*</literal> is greedy so
7357 it <quote>eats</quote> as much as it can, leaving the <literal>\d+</literal> to
7358 match at the last possible place, the last digit. We might try to fix
7359 that by making it non-greedy:
7360 <screen>
7361 SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
7362 <lineannotation>Result: </lineannotation><computeroutput>{abc,0,""}</computeroutput>
7363 </screen>
7364 That didn't work either, because now the RE as a whole is non-greedy
7365 and so it ends the overall match as soon as possible. We can get what
7366 we want by forcing the RE as a whole to be greedy:
7367 <screen>
7368 SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
7369 <lineannotation>Result: </lineannotation><computeroutput>{abc,01234,xyz}</computeroutput>
7370 </screen>
7371 Controlling the RE's overall greediness separately from its components'
7372 greediness allows great flexibility in handling variable-length patterns.
7373 </para>
7375 <para>
7376 When deciding what is a longer or shorter match,
7377 match lengths are measured in characters, not collating elements.
7378 An empty string is considered longer than no match at all.
7379 For example:
7380 <literal>bb*</literal>
7381 matches the three middle characters of <literal>abbbc</literal>;
7382 <literal>(week|wee)(night|knights)</literal>
7383 matches all ten characters of <literal>weeknights</literal>;
7384 when <literal>(.*).*</literal>
7385 is matched against <literal>abc</literal> the parenthesized subexpression
7386 matches all three characters; and when
7387 <literal>(a*)*</literal> is matched against <literal>bc</literal>
7388 both the whole RE and the parenthesized
7389 subexpression match an empty string.
7390 </para>
7392 <para>
7393 If case-independent matching is specified,
7394 the effect is much as if all case distinctions had vanished from the
7395 alphabet.
7396 When an alphabetic that exists in multiple cases appears as an
7397 ordinary character outside a bracket expression, it is effectively
7398 transformed into a bracket expression containing both cases,
7399 e.g., <literal>x</literal> becomes <literal>[xX]</literal>.
7400 When it appears inside a bracket expression, all case counterparts
7401 of it are added to the bracket expression, e.g.,
7402 <literal>[x]</literal> becomes <literal>[xX]</literal>
7403 and <literal>[^x]</literal> becomes <literal>[^xX]</literal>.
7404 </para>
7406 <para>
7407 If newline-sensitive matching is specified, <literal>.</literal>
7408 and bracket expressions using <literal>^</literal>
7409 will never match the newline character
7410 (so that matches will not cross lines unless the RE
7411 explicitly includes a newline)
7412 and <literal>^</literal> and <literal>$</literal>
7413 will match the empty string after and before a newline
7414 respectively, in addition to matching at beginning and end of string
7415 respectively.
7416 But the ARE escapes <literal>\A</literal> and <literal>\Z</literal>
7417 continue to match beginning or end of string <emphasis>only</emphasis>.
7418 Also, the character class shorthands <literal>\D</literal>
7419 and <literal>\W</literal> will match a newline regardless of this mode.
7420 (Before <productname>PostgreSQL</productname> 14, they did not match
7421 newlines when in newline-sensitive mode.
7422 Write <literal>[^[:digit:]]</literal>
7423 or <literal>[^[:word:]]</literal> to get the old behavior.)
7424 </para>
7426 <para>
7427 If partial newline-sensitive matching is specified,
7428 this affects <literal>.</literal> and bracket expressions
7429 as with newline-sensitive matching, but not <literal>^</literal>
7430 and <literal>$</literal>.
7431 </para>
7433 <para>
7434 If inverse partial newline-sensitive matching is specified,
7435 this affects <literal>^</literal> and <literal>$</literal>
7436 as with newline-sensitive matching, but not <literal>.</literal>
7437 and bracket expressions.
7438 This isn't very useful but is provided for symmetry.
7439 </para>
7440 </sect3>
7442 <sect3 id="posix-limits-compatibility">
7443 <title>Limits and Compatibility</title>
7445 <para>
7446 No particular limit is imposed on the length of REs in this
7447 implementation. However,
7448 programs intended to be highly portable should not employ REs longer
7449 than 256 bytes,
7450 as a POSIX-compliant implementation can refuse to accept such REs.
7451 </para>
7453 <para>
7454 The only feature of AREs that is actually incompatible with
7455 POSIX EREs is that <literal>\</literal> does not lose its special
7456 significance inside bracket expressions.
7457 All other ARE features use syntax which is illegal or has
7458 undefined or unspecified effects in POSIX EREs;
7459 the <literal>***</literal> syntax of directors likewise is outside the POSIX
7460 syntax for both BREs and EREs.
7461 </para>
7463 <para>
7464 Many of the ARE extensions are borrowed from Perl, but some have
7465 been changed to clean them up, and a few Perl extensions are not present.
7466 Incompatibilities of note include <literal>\b</literal>, <literal>\B</literal>,
7467 the lack of special treatment for a trailing newline,
7468 the addition of complemented bracket expressions to the things
7469 affected by newline-sensitive matching,
7470 the restrictions on parentheses and back references in lookahead/lookbehind
7471 constraints, and the longest/shortest-match (rather than first-match)
7472 matching semantics.
7473 </para>
7474 </sect3>
7476 <sect3 id="posix-basic-regexes">
7477 <title>Basic Regular Expressions</title>
7479 <para>
7480 BREs differ from EREs in several respects.
7481 In BREs, <literal>|</literal>, <literal>+</literal>, and <literal>?</literal>
7482 are ordinary characters and there is no equivalent
7483 for their functionality.
7484 The delimiters for bounds are
7485 <literal>\{</literal> and <literal>\}</literal>,
7486 with <literal>{</literal> and <literal>}</literal>
7487 by themselves ordinary characters.
7488 The parentheses for nested subexpressions are
7489 <literal>\(</literal> and <literal>\)</literal>,
7490 with <literal>(</literal> and <literal>)</literal> by themselves ordinary characters.
7491 <literal>^</literal> is an ordinary character except at the beginning of the
7492 RE or the beginning of a parenthesized subexpression,
7493 <literal>$</literal> is an ordinary character except at the end of the
7494 RE or the end of a parenthesized subexpression,
7495 and <literal>*</literal> is an ordinary character if it appears at the beginning
7496 of the RE or the beginning of a parenthesized subexpression
7497 (after a possible leading <literal>^</literal>).
7498 Finally, single-digit back references are available, and
7499 <literal>\&lt;</literal> and <literal>\&gt;</literal>
7500 are synonyms for
7501 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal>
7502 respectively; no other escapes are available in BREs.
7503 </para>
7504 </sect3>
7506 <!-- end re_syntax.n man page -->
7508 <sect3 id="posix-vs-xquery">
7509 <title>Differences from SQL Standard and XQuery</title>
7511 <indexterm zone="posix-vs-xquery">
7512 <primary>LIKE_REGEX</primary>
7513 </indexterm>
7515 <indexterm zone="posix-vs-xquery">
7516 <primary>OCCURRENCES_REGEX</primary>
7517 </indexterm>
7519 <indexterm zone="posix-vs-xquery">
7520 <primary>POSITION_REGEX</primary>
7521 </indexterm>
7523 <indexterm zone="posix-vs-xquery">
7524 <primary>SUBSTRING_REGEX</primary>
7525 </indexterm>
7527 <indexterm zone="posix-vs-xquery">
7528 <primary>TRANSLATE_REGEX</primary>
7529 </indexterm>
7531 <indexterm zone="posix-vs-xquery">
7532 <primary>XQuery regular expressions</primary>
7533 </indexterm>
7535 <para>
7536 Since SQL:2008, the SQL standard includes regular expression operators
7537 and functions that performs pattern
7538 matching according to the XQuery regular expression
7539 standard:
7540 <itemizedlist>
7541 <listitem><para><literal>LIKE_REGEX</literal></para></listitem>
7542 <listitem><para><literal>OCCURRENCES_REGEX</literal></para></listitem>
7543 <listitem><para><literal>POSITION_REGEX</literal></para></listitem>
7544 <listitem><para><literal>SUBSTRING_REGEX</literal></para></listitem>
7545 <listitem><para><literal>TRANSLATE_REGEX</literal></para></listitem>
7546 </itemizedlist>
7547 <productname>PostgreSQL</productname> does not currently implement these
7548 operators and functions. You can get approximately equivalent
7549 functionality in each case as shown in <xref
7550 linkend="functions-regexp-sql-table"/>. (Various optional clauses on
7551 both sides have been omitted in this table.)
7552 </para>
7554 <table id="functions-regexp-sql-table">
7555 <title>Regular Expression Functions Equivalencies</title>
7557 <tgroup cols="2">
7558 <thead>
7559 <row>
7560 <entry>SQL standard</entry>
7561 <entry><productname>PostgreSQL</productname></entry>
7562 </row>
7563 </thead>
7565 <tbody>
7566 <row>
7567 <entry><literal><replaceable>string</replaceable> LIKE_REGEX <replaceable>pattern</replaceable></literal></entry>
7568 <entry><literal>regexp_like(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal> or <literal><replaceable>string</replaceable> ~ <replaceable>pattern</replaceable></literal></entry>
7569 </row>
7571 <row>
7572 <entry><literal>OCCURRENCES_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7573 <entry><literal>regexp_count(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7574 </row>
7576 <row>
7577 <entry><literal>POSITION_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7578 <entry><literal>regexp_instr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7579 </row>
7581 <row>
7582 <entry><literal>SUBSTRING_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7583 <entry><literal>regexp_substr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7584 </row>
7586 <row>
7587 <entry><literal>TRANSLATE_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable> WITH <replaceable>replacement</replaceable>)</literal></entry>
7588 <entry><literal>regexp_replace(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>)</literal></entry>
7589 </row>
7590 </tbody>
7591 </tgroup>
7592 </table>
7594 <para>
7595 Regular expression functions similar to those provided by PostgreSQL are
7596 also available in a number of other SQL implementations, whereas the
7597 SQL-standard functions are not as widely implemented. Some of the
7598 details of the regular expression syntax will likely differ in each
7599 implementation.
7600 </para>
7602 <para>
7603 The SQL-standard operators and functions use XQuery regular expressions,
7604 which are quite close to the ARE syntax described above.
7605 Notable differences between the existing POSIX-based
7606 regular-expression feature and XQuery regular expressions include:
7608 <itemizedlist>
7609 <listitem>
7610 <para>
7611 XQuery character class subtraction is not supported. An example of
7612 this feature is using the following to match only English
7613 consonants: <literal>[a-z-[aeiou]]</literal>.
7614 </para>
7615 </listitem>
7616 <listitem>
7617 <para>
7618 XQuery character class shorthands <literal>\c</literal>,
7619 <literal>\C</literal>, <literal>\i</literal>,
7620 and <literal>\I</literal> are not supported.
7621 </para>
7622 </listitem>
7623 <listitem>
7624 <para>
7625 XQuery character class elements
7626 using <literal>\p{UnicodeProperty}</literal> or the
7627 inverse <literal>\P{UnicodeProperty}</literal> are not supported.
7628 </para>
7629 </listitem>
7630 <listitem>
7631 <para>
7632 POSIX interprets character classes such as <literal>\w</literal>
7633 (see <xref linkend="posix-class-shorthand-escapes-table"/>)
7634 according to the prevailing locale (which you can control by
7635 attaching a <literal>COLLATE</literal> clause to the operator or
7636 function). XQuery specifies these classes by reference to Unicode
7637 character properties, so equivalent behavior is obtained only with
7638 a locale that follows the Unicode rules.
7639 </para>
7640 </listitem>
7641 <listitem>
7642 <para>
7643 The SQL standard (not XQuery itself) attempts to cater for more
7644 variants of <quote>newline</quote> than POSIX does. The
7645 newline-sensitive matching options described above consider only
7646 ASCII NL (<literal>\n</literal>) to be a newline, but SQL would have
7647 us treat CR (<literal>\r</literal>), CRLF (<literal>\r\n</literal>)
7648 (a Windows-style newline), and some Unicode-only characters like
7649 LINE SEPARATOR (U+2028) as newlines as well.
7650 Notably, <literal>.</literal> and <literal>\s</literal> should
7651 count <literal>\r\n</literal> as one character not two according to
7652 SQL.
7653 </para>
7654 </listitem>
7655 <listitem>
7656 <para>
7657 Of the character-entry escapes described in
7658 <xref linkend="posix-character-entry-escapes-table"/>,
7659 XQuery supports only <literal>\n</literal>, <literal>\r</literal>,
7660 and <literal>\t</literal>.
7661 </para>
7662 </listitem>
7663 <listitem>
7664 <para>
7665 XQuery does not support
7666 the <literal>[:<replaceable>name</replaceable>:]</literal> syntax
7667 for character classes within bracket expressions.
7668 </para>
7669 </listitem>
7670 <listitem>
7671 <para>
7672 XQuery does not have lookahead or lookbehind constraints,
7673 nor any of the constraint escapes described in
7674 <xref linkend="posix-constraint-escapes-table"/>.
7675 </para>
7676 </listitem>
7677 <listitem>
7678 <para>
7679 The metasyntax forms described in <xref linkend="posix-metasyntax"/>
7680 do not exist in XQuery.
7681 </para>
7682 </listitem>
7683 <listitem>
7684 <para>
7685 The regular expression flag letters defined by XQuery are
7686 related to but not the same as the option letters for POSIX
7687 (<xref linkend="posix-embedded-options-table"/>). While the
7688 <literal>i</literal> and <literal>q</literal> options behave the
7689 same, others do not:
7690 <itemizedlist>
7691 <listitem>
7692 <para>
7693 XQuery's <literal>s</literal> (allow dot to match newline)
7694 and <literal>m</literal> (allow <literal>^</literal>
7695 and <literal>$</literal> to match at newlines) flags provide
7696 access to the same behaviors as
7697 POSIX's <literal>n</literal>, <literal>p</literal>
7698 and <literal>w</literal> flags, but they
7699 do <emphasis>not</emphasis> match the behavior of
7700 POSIX's <literal>s</literal> and <literal>m</literal> flags.
7701 Note in particular that dot-matches-newline is the default
7702 behavior in POSIX but not XQuery.
7703 </para>
7704 </listitem>
7705 <listitem>
7706 <para>
7707 XQuery's <literal>x</literal> (ignore whitespace in pattern) flag
7708 is noticeably different from POSIX's expanded-mode flag.
7709 POSIX's <literal>x</literal> flag also
7710 allows <literal>#</literal> to begin a comment in the pattern,
7711 and POSIX will not ignore a whitespace character after a
7712 backslash.
7713 </para>
7714 </listitem>
7715 </itemizedlist>
7716 </para>
7717 </listitem>
7718 </itemizedlist>
7719 </para>
7721 </sect3>
7722 </sect2>
7723 </sect1>
7726 <sect1 id="functions-formatting">
7727 <title>Data Type Formatting Functions</title>
7729 <indexterm>
7730 <primary>formatting</primary>
7731 </indexterm>
7733 <para>
7734 The <productname>PostgreSQL</productname> formatting functions
7735 provide a powerful set of tools for converting various data types
7736 (date/time, integer, floating point, numeric) to formatted strings
7737 and for converting from formatted strings to specific data types.
7738 <xref linkend="functions-formatting-table"/> lists them.
7739 These functions all follow a common calling convention: the first
7740 argument is the value to be formatted and the second argument is a
7741 template that defines the output or input format.
7742 </para>
7744 <table id="functions-formatting-table">
7745 <title>Formatting Functions</title>
7746 <tgroup cols="1">
7747 <thead>
7748 <row>
7749 <entry role="func_table_entry"><para role="func_signature">
7750 Function
7751 </para>
7752 <para>
7753 Description
7754 </para>
7755 <para>
7756 Example(s)
7757 </para></entry>
7758 </row>
7759 </thead>
7761 <tbody>
7762 <row>
7763 <entry role="func_table_entry"><para role="func_signature">
7764 <indexterm>
7765 <primary>to_char</primary>
7766 </indexterm>
7767 <function>to_char</function> ( <type>timestamp</type>, <type>text</type> )
7768 <returnvalue>text</returnvalue>
7769 </para>
7770 <para role="func_signature">
7771 <function>to_char</function> ( <type>timestamp with time zone</type>, <type>text</type> )
7772 <returnvalue>text</returnvalue>
7773 </para>
7774 <para>
7775 Converts time stamp to string according to the given format.
7776 </para>
7777 <para>
7778 <literal>to_char(timestamp '2002-04-20 17:31:12.66', 'HH12:MI:SS')</literal>
7779 <returnvalue>05:31:12</returnvalue>
7780 </para></entry>
7781 </row>
7783 <row>
7784 <entry role="func_table_entry"><para role="func_signature">
7785 <function>to_char</function> ( <type>interval</type>, <type>text</type> )
7786 <returnvalue>text</returnvalue>
7787 </para>
7788 <para>
7789 Converts interval to string according to the given format.
7790 </para>
7791 <para>
7792 <literal>to_char(interval '15h 2m 12s', 'HH24:MI:SS')</literal>
7793 <returnvalue>15:02:12</returnvalue>
7794 </para></entry>
7795 </row>
7797 <row>
7798 <entry role="func_table_entry"><para role="func_signature">
7799 <function>to_char</function> ( <replaceable>numeric_type</replaceable>, <type>text</type> )
7800 <returnvalue>text</returnvalue>
7801 </para>
7802 <para>
7803 Converts number to string according to the given format; available
7804 for <type>integer</type>, <type>bigint</type>, <type>numeric</type>,
7805 <type>real</type>, <type>double precision</type>.
7806 </para>
7807 <para>
7808 <literal>to_char(125, '999')</literal>
7809 <returnvalue>125</returnvalue>
7810 </para>
7811 <para>
7812 <literal>to_char(125.8::real, '999D9')</literal>
7813 <returnvalue>125.8</returnvalue>
7814 </para>
7815 <para>
7816 <literal>to_char(-125.8, '999D99S')</literal>
7817 <returnvalue>125.80-</returnvalue>
7818 </para></entry>
7819 </row>
7821 <row>
7822 <entry role="func_table_entry"><para role="func_signature">
7823 <indexterm>
7824 <primary>to_date</primary>
7825 </indexterm>
7826 <function>to_date</function> ( <type>text</type>, <type>text</type> )
7827 <returnvalue>date</returnvalue>
7828 </para>
7829 <para>
7830 Converts string to date according to the given format.
7831 </para>
7832 <para>
7833 <literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal>
7834 <returnvalue>2000-12-05</returnvalue>
7835 </para></entry>
7836 </row>
7838 <row>
7839 <entry role="func_table_entry"><para role="func_signature">
7840 <indexterm>
7841 <primary>to_number</primary>
7842 </indexterm>
7843 <function>to_number</function> ( <type>text</type>, <type>text</type> )
7844 <returnvalue>numeric</returnvalue>
7845 </para>
7846 <para>
7847 Converts string to numeric according to the given format.
7848 </para>
7849 <para>
7850 <literal>to_number('12,454.8-', '99G999D9S')</literal>
7851 <returnvalue>-12454.8</returnvalue>
7852 </para></entry>
7853 </row>
7855 <row>
7856 <entry role="func_table_entry"><para role="func_signature">
7857 <indexterm>
7858 <primary>to_timestamp</primary>
7859 </indexterm>
7860 <function>to_timestamp</function> ( <type>text</type>, <type>text</type> )
7861 <returnvalue>timestamp with time zone</returnvalue>
7862 </para>
7863 <para>
7864 Converts string to time stamp according to the given format.
7865 (See also <function>to_timestamp(double precision)</function> in
7866 <xref linkend="functions-datetime-table"/>.)
7867 </para>
7868 <para>
7869 <literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal>
7870 <returnvalue>2000-12-05 00:00:00-05</returnvalue>
7871 </para></entry>
7872 </row>
7873 </tbody>
7874 </tgroup>
7875 </table>
7877 <tip>
7878 <para>
7879 <function>to_timestamp</function> and <function>to_date</function>
7880 exist to handle input formats that cannot be converted by
7881 simple casting. For most standard date/time formats, simply casting the
7882 source string to the required data type works, and is much easier.
7883 Similarly, <function>to_number</function> is unnecessary for standard numeric
7884 representations.
7885 </para>
7886 </tip>
7888 <para>
7889 In a <function>to_char</function> output template string, there are certain
7890 patterns that are recognized and replaced with appropriately-formatted
7891 data based on the given value. Any text that is not a template pattern is
7892 simply copied verbatim. Similarly, in an input template string (for the
7893 other functions), template patterns identify the values to be supplied by
7894 the input data string. If there are characters in the template string
7895 that are not template patterns, the corresponding characters in the input
7896 data string are simply skipped over (whether or not they are equal to the
7897 template string characters).
7898 </para>
7900 <para>
7901 <xref linkend="functions-formatting-datetime-table"/> shows the
7902 template patterns available for formatting date and time values.
7903 </para>
7905 <table id="functions-formatting-datetime-table">
7906 <title>Template Patterns for Date/Time Formatting</title>
7907 <tgroup cols="2">
7908 <thead>
7909 <row>
7910 <entry>Pattern</entry>
7911 <entry>Description</entry>
7912 </row>
7913 </thead>
7914 <tbody>
7915 <row>
7916 <entry><literal>HH</literal></entry>
7917 <entry>hour of day (01&ndash;12)</entry>
7918 </row>
7919 <row>
7920 <entry><literal>HH12</literal></entry>
7921 <entry>hour of day (01&ndash;12)</entry>
7922 </row>
7923 <row>
7924 <entry><literal>HH24</literal></entry>
7925 <entry>hour of day (00&ndash;23)</entry>
7926 </row>
7927 <row>
7928 <entry><literal>MI</literal></entry>
7929 <entry>minute (00&ndash;59)</entry>
7930 </row>
7931 <row>
7932 <entry><literal>SS</literal></entry>
7933 <entry>second (00&ndash;59)</entry>
7934 </row>
7935 <row>
7936 <entry><literal>MS</literal></entry>
7937 <entry>millisecond (000&ndash;999)</entry>
7938 </row>
7939 <row>
7940 <entry><literal>US</literal></entry>
7941 <entry>microsecond (000000&ndash;999999)</entry>
7942 </row>
7943 <row>
7944 <entry><literal>FF1</literal></entry>
7945 <entry>tenth of second (0&ndash;9)</entry>
7946 </row>
7947 <row>
7948 <entry><literal>FF2</literal></entry>
7949 <entry>hundredth of second (00&ndash;99)</entry>
7950 </row>
7951 <row>
7952 <entry><literal>FF3</literal></entry>
7953 <entry>millisecond (000&ndash;999)</entry>
7954 </row>
7955 <row>
7956 <entry><literal>FF4</literal></entry>
7957 <entry>tenth of a millisecond (0000&ndash;9999)</entry>
7958 </row>
7959 <row>
7960 <entry><literal>FF5</literal></entry>
7961 <entry>hundredth of a millisecond (00000&ndash;99999)</entry>
7962 </row>
7963 <row>
7964 <entry><literal>FF6</literal></entry>
7965 <entry>microsecond (000000&ndash;999999)</entry>
7966 </row>
7967 <row>
7968 <entry><literal>SSSS</literal>, <literal>SSSSS</literal></entry>
7969 <entry>seconds past midnight (0&ndash;86399)</entry>
7970 </row>
7971 <row>
7972 <entry><literal>AM</literal>, <literal>am</literal>,
7973 <literal>PM</literal> or <literal>pm</literal></entry>
7974 <entry>meridiem indicator (without periods)</entry>
7975 </row>
7976 <row>
7977 <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
7978 <literal>P.M.</literal> or <literal>p.m.</literal></entry>
7979 <entry>meridiem indicator (with periods)</entry>
7980 </row>
7981 <row>
7982 <entry><literal>Y,YYY</literal></entry>
7983 <entry>year (4 or more digits) with comma</entry>
7984 </row>
7985 <row>
7986 <entry><literal>YYYY</literal></entry>
7987 <entry>year (4 or more digits)</entry>
7988 </row>
7989 <row>
7990 <entry><literal>YYY</literal></entry>
7991 <entry>last 3 digits of year</entry>
7992 </row>
7993 <row>
7994 <entry><literal>YY</literal></entry>
7995 <entry>last 2 digits of year</entry>
7996 </row>
7997 <row>
7998 <entry><literal>Y</literal></entry>
7999 <entry>last digit of year</entry>
8000 </row>
8001 <row>
8002 <entry><literal>IYYY</literal></entry>
8003 <entry>ISO 8601 week-numbering year (4 or more digits)</entry>
8004 </row>
8005 <row>
8006 <entry><literal>IYY</literal></entry>
8007 <entry>last 3 digits of ISO 8601 week-numbering year</entry>
8008 </row>
8009 <row>
8010 <entry><literal>IY</literal></entry>
8011 <entry>last 2 digits of ISO 8601 week-numbering year</entry>
8012 </row>
8013 <row>
8014 <entry><literal>I</literal></entry>
8015 <entry>last digit of ISO 8601 week-numbering year</entry>
8016 </row>
8017 <row>
8018 <entry><literal>BC</literal>, <literal>bc</literal>,
8019 <literal>AD</literal> or <literal>ad</literal></entry>
8020 <entry>era indicator (without periods)</entry>
8021 </row>
8022 <row>
8023 <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
8024 <literal>A.D.</literal> or <literal>a.d.</literal></entry>
8025 <entry>era indicator (with periods)</entry>
8026 </row>
8027 <row>
8028 <entry><literal>MONTH</literal></entry>
8029 <entry>full upper case month name (blank-padded to 9 chars)</entry>
8030 </row>
8031 <row>
8032 <entry><literal>Month</literal></entry>
8033 <entry>full capitalized month name (blank-padded to 9 chars)</entry>
8034 </row>
8035 <row>
8036 <entry><literal>month</literal></entry>
8037 <entry>full lower case month name (blank-padded to 9 chars)</entry>
8038 </row>
8039 <row>
8040 <entry><literal>MON</literal></entry>
8041 <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
8042 </row>
8043 <row>
8044 <entry><literal>Mon</literal></entry>
8045 <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
8046 </row>
8047 <row>
8048 <entry><literal>mon</literal></entry>
8049 <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
8050 </row>
8051 <row>
8052 <entry><literal>MM</literal></entry>
8053 <entry>month number (01&ndash;12)</entry>
8054 </row>
8055 <row>
8056 <entry><literal>DAY</literal></entry>
8057 <entry>full upper case day name (blank-padded to 9 chars)</entry>
8058 </row>
8059 <row>
8060 <entry><literal>Day</literal></entry>
8061 <entry>full capitalized day name (blank-padded to 9 chars)</entry>
8062 </row>
8063 <row>
8064 <entry><literal>day</literal></entry>
8065 <entry>full lower case day name (blank-padded to 9 chars)</entry>
8066 </row>
8067 <row>
8068 <entry><literal>DY</literal></entry>
8069 <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
8070 </row>
8071 <row>
8072 <entry><literal>Dy</literal></entry>
8073 <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
8074 </row>
8075 <row>
8076 <entry><literal>dy</literal></entry>
8077 <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
8078 </row>
8079 <row>
8080 <entry><literal>DDD</literal></entry>
8081 <entry>day of year (001&ndash;366)</entry>
8082 </row>
8083 <row>
8084 <entry><literal>IDDD</literal></entry>
8085 <entry>day of ISO 8601 week-numbering year (001&ndash;371; day 1 of the year is Monday of the first ISO week)</entry>
8086 </row>
8087 <row>
8088 <entry><literal>DD</literal></entry>
8089 <entry>day of month (01&ndash;31)</entry>
8090 </row>
8091 <row>
8092 <entry><literal>D</literal></entry>
8093 <entry>day of the week, Sunday (<literal>1</literal>) to Saturday (<literal>7</literal>)</entry>
8094 </row>
8095 <row>
8096 <entry><literal>ID</literal></entry>
8097 <entry>ISO 8601 day of the week, Monday (<literal>1</literal>) to Sunday (<literal>7</literal>)</entry>
8098 </row>
8099 <row>
8100 <entry><literal>W</literal></entry>
8101 <entry>week of month (1&ndash;5) (the first week starts on the first day of the month)</entry>
8102 </row>
8103 <row>
8104 <entry><literal>WW</literal></entry>
8105 <entry>week number of year (1&ndash;53) (the first week starts on the first day of the year)</entry>
8106 </row>
8107 <row>
8108 <entry><literal>IW</literal></entry>
8109 <entry>week number of ISO 8601 week-numbering year (01&ndash;53; the first Thursday of the year is in week 1)</entry>
8110 </row>
8111 <row>
8112 <entry><literal>CC</literal></entry>
8113 <entry>century (2 digits) (the twenty-first century starts on 2001-01-01)</entry>
8114 </row>
8115 <row>
8116 <entry><literal>J</literal></entry>
8117 <entry>Julian Date (integer days since November 24, 4714 BC at local
8118 midnight; see <xref linkend="datetime-julian-dates"/>)</entry>
8119 </row>
8120 <row>
8121 <entry><literal>Q</literal></entry>
8122 <entry>quarter</entry>
8123 </row>
8124 <row>
8125 <entry><literal>RM</literal></entry>
8126 <entry>month in upper case Roman numerals (I&ndash;XII; I=January)</entry>
8127 </row>
8128 <row>
8129 <entry><literal>rm</literal></entry>
8130 <entry>month in lower case Roman numerals (i&ndash;xii; i=January)</entry>
8131 </row>
8132 <row>
8133 <entry><literal>TZ</literal></entry>
8134 <entry>upper case time-zone abbreviation
8135 (only supported in <function>to_char</function>)</entry>
8136 </row>
8137 <row>
8138 <entry><literal>tz</literal></entry>
8139 <entry>lower case time-zone abbreviation
8140 (only supported in <function>to_char</function>)</entry>
8141 </row>
8142 <row>
8143 <entry><literal>TZH</literal></entry>
8144 <entry>time-zone hours</entry>
8145 </row>
8146 <row>
8147 <entry><literal>TZM</literal></entry>
8148 <entry>time-zone minutes</entry>
8149 </row>
8150 <row>
8151 <entry><literal>OF</literal></entry>
8152 <entry>time-zone offset from UTC
8153 (only supported in <function>to_char</function>)</entry>
8154 </row>
8155 </tbody>
8156 </tgroup>
8157 </table>
8159 <para>
8160 Modifiers can be applied to any template pattern to alter its
8161 behavior. For example, <literal>FMMonth</literal>
8162 is the <literal>Month</literal> pattern with the
8163 <literal>FM</literal> modifier.
8164 <xref linkend="functions-formatting-datetimemod-table"/> shows the
8165 modifier patterns for date/time formatting.
8166 </para>
8168 <table id="functions-formatting-datetimemod-table">
8169 <title>Template Pattern Modifiers for Date/Time Formatting</title>
8170 <tgroup cols="3">
8171 <thead>
8172 <row>
8173 <entry>Modifier</entry>
8174 <entry>Description</entry>
8175 <entry>Example</entry>
8176 </row>
8177 </thead>
8178 <tbody>
8179 <row>
8180 <entry><literal>FM</literal> prefix</entry>
8181 <entry>fill mode (suppress leading zeroes and padding blanks)</entry>
8182 <entry><literal>FMMonth</literal></entry>
8183 </row>
8184 <row>
8185 <entry><literal>TH</literal> suffix</entry>
8186 <entry>upper case ordinal number suffix</entry>
8187 <entry><literal>DDTH</literal>, e.g., <literal>12TH</literal></entry>
8188 </row>
8189 <row>
8190 <entry><literal>th</literal> suffix</entry>
8191 <entry>lower case ordinal number suffix</entry>
8192 <entry><literal>DDth</literal>, e.g., <literal>12th</literal></entry>
8193 </row>
8194 <row>
8195 <entry><literal>FX</literal> prefix</entry>
8196 <entry>fixed format global option (see usage notes)</entry>
8197 <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
8198 </row>
8199 <row>
8200 <entry><literal>TM</literal> prefix</entry>
8201 <entry>translation mode (use localized day and month names based on
8202 <xref linkend="guc-lc-time"/>)</entry>
8203 <entry><literal>TMMonth</literal></entry>
8204 </row>
8205 <row>
8206 <entry><literal>SP</literal> suffix</entry>
8207 <entry>spell mode (not implemented)</entry>
8208 <entry><literal>DDSP</literal></entry>
8209 </row>
8210 </tbody>
8211 </tgroup>
8212 </table>
8214 <para>
8215 Usage notes for date/time formatting:
8217 <itemizedlist>
8218 <listitem>
8219 <para>
8220 <literal>FM</literal> suppresses leading zeroes and trailing blanks
8221 that would otherwise be added to make the output of a pattern be
8222 fixed-width. In <productname>PostgreSQL</productname>,
8223 <literal>FM</literal> modifies only the next specification, while in
8224 Oracle <literal>FM</literal> affects all subsequent
8225 specifications, and repeated <literal>FM</literal> modifiers
8226 toggle fill mode on and off.
8227 </para>
8228 </listitem>
8230 <listitem>
8231 <para>
8232 <literal>TM</literal> suppresses trailing blanks whether or
8233 not <literal>FM</literal> is specified.
8234 </para>
8235 </listitem>
8237 <listitem>
8238 <para>
8239 <function>to_timestamp</function> and <function>to_date</function>
8240 ignore letter case in the input; so for
8241 example <literal>MON</literal>, <literal>Mon</literal>,
8242 and <literal>mon</literal> all accept the same strings. When using
8243 the <literal>TM</literal> modifier, case-folding is done according to
8244 the rules of the function's input collation (see
8245 <xref linkend="collation"/>).
8246 </para>
8247 </listitem>
8249 <listitem>
8250 <para>
8251 <function>to_timestamp</function> and <function>to_date</function>
8252 skip multiple blank spaces at the beginning of the input string and
8253 around date and time values unless the <literal>FX</literal> option is used. For example,
8254 <literal>to_timestamp('&nbsp;2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> and
8255 <literal>to_timestamp('2000 - JUN', 'YYYY-MON')</literal> work, but
8256 <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
8257 because <function>to_timestamp</function> expects only a single space.
8258 <literal>FX</literal> must be specified as the first item in
8259 the template.
8260 </para>
8261 </listitem>
8263 <listitem>
8264 <para>
8265 A separator (a space or non-letter/non-digit character) in the template string of
8266 <function>to_timestamp</function> and <function>to_date</function>
8267 matches any single separator in the input string or is skipped,
8268 unless the <literal>FX</literal> option is used.
8269 For example, <literal>to_timestamp('2000JUN', 'YYYY///MON')</literal> and
8270 <literal>to_timestamp('2000/JUN', 'YYYY MON')</literal> work, but
8271 <literal>to_timestamp('2000//JUN', 'YYYY/MON')</literal>
8272 returns an error because the number of separators in the input string
8273 exceeds the number of separators in the template.
8274 </para>
8275 <para>
8276 If <literal>FX</literal> is specified, a separator in the template string
8277 matches exactly one character in the input string. But note that the
8278 input string character is not required to be the same as the separator from the template string.
8279 For example, <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal>
8280 works, but <literal>to_timestamp('2000/JUN', 'FXYYYY&nbsp;&nbsp;MON')</literal>
8281 returns an error because the second space in the template string consumes
8282 the letter <literal>J</literal> from the input string.
8283 </para>
8284 </listitem>
8286 <listitem>
8287 <para>
8288 A <literal>TZH</literal> template pattern can match a signed number.
8289 Without the <literal>FX</literal> option, minus signs may be ambiguous,
8290 and could be interpreted as a separator.
8291 This ambiguity is resolved as follows: If the number of separators before
8292 <literal>TZH</literal> in the template string is less than the number of
8293 separators before the minus sign in the input string, the minus sign
8294 is interpreted as part of <literal>TZH</literal>.
8295 Otherwise, the minus sign is considered to be a separator between values.
8296 For example, <literal>to_timestamp('2000 -10', 'YYYY TZH')</literal> matches
8297 <literal>-10</literal> to <literal>TZH</literal>, but
8298 <literal>to_timestamp('2000 -10', 'YYYY&nbsp;&nbsp;TZH')</literal>
8299 matches <literal>10</literal> to <literal>TZH</literal>.
8300 </para>
8301 </listitem>
8303 <listitem>
8304 <para>
8305 Ordinary text is allowed in <function>to_char</function>
8306 templates and will be output literally. You can put a substring
8307 in double quotes to force it to be interpreted as literal text
8308 even if it contains template patterns. For example, in
8309 <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
8310 will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
8311 will not be.
8312 In <function>to_date</function>, <function>to_number</function>,
8313 and <function>to_timestamp</function>, literal text and double-quoted
8314 strings result in skipping the number of characters contained in the
8315 string; for example <literal>"XX"</literal> skips two input characters
8316 (whether or not they are <literal>XX</literal>).
8317 </para>
8318 <tip>
8319 <para>
8320 Prior to <productname>PostgreSQL</productname> 12, it was possible to
8321 skip arbitrary text in the input string using non-letter or non-digit
8322 characters. For example,
8323 <literal>to_timestamp('2000y6m1d', 'yyyy-MM-DD')</literal> used to
8324 work. Now you can only use letter characters for this purpose. For example,
8325 <literal>to_timestamp('2000y6m1d', 'yyyytMMtDDt')</literal> and
8326 <literal>to_timestamp('2000y6m1d', 'yyyy"y"MM"m"DD"d"')</literal>
8327 skip <literal>y</literal>, <literal>m</literal>, and
8328 <literal>d</literal>.
8329 </para>
8330 </tip>
8331 </listitem>
8333 <listitem>
8334 <para>
8335 If you want to have a double quote in the output you must
8336 precede it with a backslash, for example <literal>'\"YYYY
8337 Month\"'</literal>. <!-- "" font-lock sanity :-) -->
8338 Backslashes are not otherwise special outside of double-quoted
8339 strings. Within a double-quoted string, a backslash causes the
8340 next character to be taken literally, whatever it is (but this
8341 has no special effect unless the next character is a double quote
8342 or another backslash).
8343 </para>
8344 </listitem>
8346 <listitem>
8347 <para>
8348 In <function>to_timestamp</function> and <function>to_date</function>,
8349 if the year format specification is less than four digits, e.g.,
8350 <literal>YYY</literal>, and the supplied year is less than four digits,
8351 the year will be adjusted to be nearest to the year 2020, e.g.,
8352 <literal>95</literal> becomes 1995.
8353 </para>
8354 </listitem>
8356 <listitem>
8357 <para>
8358 In <function>to_timestamp</function> and <function>to_date</function>,
8359 negative years are treated as signifying BC. If you write both a
8360 negative year and an explicit <literal>BC</literal> field, you get AD
8361 again. An input of year zero is treated as 1 BC.
8362 </para>
8363 </listitem>
8365 <listitem>
8366 <para>
8367 In <function>to_timestamp</function> and <function>to_date</function>,
8368 the <literal>YYYY</literal> conversion has a restriction when
8369 processing years with more than 4 digits. You must
8370 use some non-digit character or template after <literal>YYYY</literal>,
8371 otherwise the year is always interpreted as 4 digits. For example
8372 (with the year 20000):
8373 <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
8374 interpreted as a 4-digit year; instead use a non-digit
8375 separator after the year, like
8376 <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
8377 <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
8378 </para>
8379 </listitem>
8381 <listitem>
8382 <para>
8383 In <function>to_timestamp</function> and <function>to_date</function>,
8384 the <literal>CC</literal> (century) field is accepted but ignored
8385 if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
8386 <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
8387 <literal>YY</literal> or <literal>Y</literal> then the result is
8388 computed as that year in the specified century. If the century is
8389 specified but the year is not, the first year of the century
8390 is assumed.
8391 </para>
8392 </listitem>
8394 <listitem>
8395 <para>
8396 In <function>to_timestamp</function> and <function>to_date</function>,
8397 weekday names or numbers (<literal>DAY</literal>, <literal>D</literal>,
8398 and related field types) are accepted but are ignored for purposes of
8399 computing the result. The same is true for quarter
8400 (<literal>Q</literal>) fields.
8401 </para>
8402 </listitem>
8404 <listitem>
8405 <para>
8406 In <function>to_timestamp</function> and <function>to_date</function>,
8407 an ISO 8601 week-numbering date (as distinct from a Gregorian date)
8408 can be specified in one of two ways:
8409 <itemizedlist>
8410 <listitem>
8411 <para>
8412 Year, week number, and weekday: for
8413 example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal>
8414 returns the date <literal>2006-10-19</literal>.
8415 If you omit the weekday it is assumed to be 1 (Monday).
8416 </para>
8417 </listitem>
8418 <listitem>
8419 <para>
8420 Year and day of year: for example <literal>to_date('2006-291',
8421 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
8422 </para>
8423 </listitem>
8424 </itemizedlist>
8425 </para>
8426 <para>
8427 Attempting to enter a date using a mixture of ISO 8601 week-numbering
8428 fields and Gregorian date fields is nonsensical, and will cause an
8429 error. In the context of an ISO 8601 week-numbering year, the
8430 concept of a <quote>month</quote> or <quote>day of month</quote> has no
8431 meaning. In the context of a Gregorian year, the ISO week has no
8432 meaning.
8433 </para>
8434 <caution>
8435 <para>
8436 While <function>to_date</function> will reject a mixture of
8437 Gregorian and ISO week-numbering date
8438 fields, <function>to_char</function> will not, since output format
8439 specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</literal> can be
8440 useful. But avoid writing something like <literal>IYYY-MM-DD</literal>;
8441 that would yield surprising results near the start of the year.
8442 (See <xref linkend="functions-datetime-extract"/> for more
8443 information.)
8444 </para>
8445 </caution>
8446 </listitem>
8448 <listitem>
8449 <para>
8450 In <function>to_timestamp</function>, millisecond
8451 (<literal>MS</literal>) or microsecond (<literal>US</literal>)
8452 fields are used as the
8453 seconds digits after the decimal point. For example
8454 <literal>to_timestamp('12.3', 'SS.MS')</literal> is not 3 milliseconds,
8455 but 300, because the conversion treats it as 12 + 0.3 seconds.
8456 So, for the format <literal>SS.MS</literal>, the input values
8457 <literal>12.3</literal>, <literal>12.30</literal>,
8458 and <literal>12.300</literal> specify the
8459 same number of milliseconds. To get three milliseconds, one must write
8460 <literal>12.003</literal>, which the conversion treats as
8461 12 + 0.003 = 12.003 seconds.
8462 </para>
8464 <para>
8465 Here is a more
8466 complex example:
8467 <literal>to_timestamp('15:12:02.020.001230', 'HH24:MI:SS.MS.US')</literal>
8468 is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
8469 1230 microseconds = 2.021230 seconds.
8470 </para>
8471 </listitem>
8473 <listitem>
8474 <para>
8475 <function>to_char(..., 'ID')</function>'s day of the week numbering
8476 matches the <function>extract(isodow from ...)</function> function, but
8477 <function>to_char(..., 'D')</function>'s does not match
8478 <function>extract(dow from ...)</function>'s day numbering.
8479 </para>
8480 </listitem>
8482 <listitem>
8483 <para>
8484 <function>to_char(interval)</function> formats <literal>HH</literal> and
8485 <literal>HH12</literal> as shown on a 12-hour clock, for example zero hours
8486 and 36 hours both output as <literal>12</literal>, while <literal>HH24</literal>
8487 outputs the full hour value, which can exceed 23 in
8488 an <type>interval</type> value.
8489 </para>
8490 </listitem>
8492 </itemizedlist>
8493 </para>
8495 <para>
8496 <xref linkend="functions-formatting-numeric-table"/> shows the
8497 template patterns available for formatting numeric values.
8498 </para>
8500 <table id="functions-formatting-numeric-table">
8501 <title>Template Patterns for Numeric Formatting</title>
8502 <tgroup cols="2">
8503 <thead>
8504 <row>
8505 <entry>Pattern</entry>
8506 <entry>Description</entry>
8507 </row>
8508 </thead>
8509 <tbody>
8510 <row>
8511 <entry><literal>9</literal></entry>
8512 <entry>digit position (can be dropped if insignificant)</entry>
8513 </row>
8514 <row>
8515 <entry><literal>0</literal></entry>
8516 <entry>digit position (will not be dropped, even if insignificant)</entry>
8517 </row>
8518 <row>
8519 <entry><literal>.</literal> (period)</entry>
8520 <entry>decimal point</entry>
8521 </row>
8522 <row>
8523 <entry><literal>,</literal> (comma)</entry>
8524 <entry>group (thousands) separator</entry>
8525 </row>
8526 <row>
8527 <entry><literal>PR</literal></entry>
8528 <entry>negative value in angle brackets</entry>
8529 </row>
8530 <row>
8531 <entry><literal>S</literal></entry>
8532 <entry>sign anchored to number (uses locale)</entry>
8533 </row>
8534 <row>
8535 <entry><literal>L</literal></entry>
8536 <entry>currency symbol (uses locale)</entry>
8537 </row>
8538 <row>
8539 <entry><literal>D</literal></entry>
8540 <entry>decimal point (uses locale)</entry>
8541 </row>
8542 <row>
8543 <entry><literal>G</literal></entry>
8544 <entry>group separator (uses locale)</entry>
8545 </row>
8546 <row>
8547 <entry><literal>MI</literal></entry>
8548 <entry>minus sign in specified position (if number &lt; 0)</entry>
8549 </row>
8550 <row>
8551 <entry><literal>PL</literal></entry>
8552 <entry>plus sign in specified position (if number &gt; 0)</entry>
8553 </row>
8554 <row>
8555 <entry><literal>SG</literal></entry>
8556 <entry>plus/minus sign in specified position</entry>
8557 </row>
8558 <row>
8559 <entry><literal>RN</literal></entry>
8560 <entry>Roman numeral (input between 1 and 3999)</entry>
8561 </row>
8562 <row>
8563 <entry><literal>TH</literal> or <literal>th</literal></entry>
8564 <entry>ordinal number suffix</entry>
8565 </row>
8566 <row>
8567 <entry><literal>V</literal></entry>
8568 <entry>shift specified number of digits (see notes)</entry>
8569 </row>
8570 <row>
8571 <entry><literal>EEEE</literal></entry>
8572 <entry>exponent for scientific notation</entry>
8573 </row>
8574 </tbody>
8575 </tgroup>
8576 </table>
8578 <para>
8579 Usage notes for numeric formatting:
8581 <itemizedlist>
8582 <listitem>
8583 <para>
8584 <literal>0</literal> specifies a digit position that will always be printed,
8585 even if it contains a leading/trailing zero. <literal>9</literal> also
8586 specifies a digit position, but if it is a leading zero then it will
8587 be replaced by a space, while if it is a trailing zero and fill mode
8588 is specified then it will be deleted. (For <function>to_number()</function>,
8589 these two pattern characters are equivalent.)
8590 </para>
8591 </listitem>
8593 <listitem>
8594 <para>
8595 If the format provides fewer fractional digits than the number being
8596 formatted, <function>to_char()</function> will round the number to
8597 the specified number of fractional digits.
8598 </para>
8599 </listitem>
8601 <listitem>
8602 <para>
8603 The pattern characters <literal>S</literal>, <literal>L</literal>, <literal>D</literal>,
8604 and <literal>G</literal> represent the sign, currency symbol, decimal point,
8605 and thousands separator characters defined by the current locale
8606 (see <xref linkend="guc-lc-monetary"/>
8607 and <xref linkend="guc-lc-numeric"/>). The pattern characters period
8608 and comma represent those exact characters, with the meanings of
8609 decimal point and thousands separator, regardless of locale.
8610 </para>
8611 </listitem>
8613 <listitem>
8614 <para>
8615 If no explicit provision is made for a sign
8616 in <function>to_char()</function>'s pattern, one column will be reserved for
8617 the sign, and it will be anchored to (appear just left of) the
8618 number. If <literal>S</literal> appears just left of some <literal>9</literal>'s,
8619 it will likewise be anchored to the number.
8620 </para>
8621 </listitem>
8623 <listitem>
8624 <para>
8625 A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
8626 <literal>MI</literal> is not anchored to
8627 the number; for example,
8628 <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
8629 but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
8630 (The Oracle implementation does not allow the use of
8631 <literal>MI</literal> before <literal>9</literal>, but rather
8632 requires that <literal>9</literal> precede
8633 <literal>MI</literal>.)
8634 </para>
8635 </listitem>
8637 <listitem>
8638 <para>
8639 <literal>TH</literal> does not convert values less than zero
8640 and does not convert fractional numbers.
8641 </para>
8642 </listitem>
8644 <listitem>
8645 <para>
8646 <literal>PL</literal>, <literal>SG</literal>, and
8647 <literal>TH</literal> are <productname>PostgreSQL</productname>
8648 extensions.
8649 </para>
8650 </listitem>
8652 <listitem>
8653 <para>
8654 In <function>to_number</function>, if non-data template patterns such
8655 as <literal>L</literal> or <literal>TH</literal> are used, the
8656 corresponding number of input characters are skipped, whether or not
8657 they match the template pattern, unless they are data characters
8658 (that is, digits, sign, decimal point, or comma). For
8659 example, <literal>TH</literal> would skip two non-data characters.
8660 </para>
8661 </listitem>
8663 <listitem>
8664 <para>
8665 <literal>V</literal> with <function>to_char</function>
8666 multiplies the input values by
8667 <literal>10^<replaceable>n</replaceable></literal>, where
8668 <replaceable>n</replaceable> is the number of digits following
8669 <literal>V</literal>. <literal>V</literal> with
8670 <function>to_number</function> divides in a similar manner.
8671 <function>to_char</function> and <function>to_number</function>
8672 do not support the use of
8673 <literal>V</literal> combined with a decimal point
8674 (e.g., <literal>99.9V99</literal> is not allowed).
8675 </para>
8676 </listitem>
8678 <listitem>
8679 <para>
8680 <literal>EEEE</literal> (scientific notation) cannot be used in
8681 combination with any of the other formatting patterns or
8682 modifiers other than digit and decimal point patterns, and must be at the end of the format string
8683 (e.g., <literal>9.99EEEE</literal> is a valid pattern).
8684 </para>
8685 </listitem>
8686 </itemizedlist>
8687 </para>
8689 <para>
8690 Certain modifiers can be applied to any template pattern to alter its
8691 behavior. For example, <literal>FM99.99</literal>
8692 is the <literal>99.99</literal> pattern with the
8693 <literal>FM</literal> modifier.
8694 <xref linkend="functions-formatting-numericmod-table"/> shows the
8695 modifier patterns for numeric formatting.
8696 </para>
8698 <table id="functions-formatting-numericmod-table">
8699 <title>Template Pattern Modifiers for Numeric Formatting</title>
8700 <tgroup cols="3">
8701 <thead>
8702 <row>
8703 <entry>Modifier</entry>
8704 <entry>Description</entry>
8705 <entry>Example</entry>
8706 </row>
8707 </thead>
8708 <tbody>
8709 <row>
8710 <entry><literal>FM</literal> prefix</entry>
8711 <entry>fill mode (suppress trailing zeroes and padding blanks)</entry>
8712 <entry><literal>FM99.99</literal></entry>
8713 </row>
8714 <row>
8715 <entry><literal>TH</literal> suffix</entry>
8716 <entry>upper case ordinal number suffix</entry>
8717 <entry><literal>999TH</literal></entry>
8718 </row>
8719 <row>
8720 <entry><literal>th</literal> suffix</entry>
8721 <entry>lower case ordinal number suffix</entry>
8722 <entry><literal>999th</literal></entry>
8723 </row>
8724 </tbody>
8725 </tgroup>
8726 </table>
8728 <para>
8729 <xref linkend="functions-formatting-examples-table"/> shows some
8730 examples of the use of the <function>to_char</function> function.
8731 </para>
8733 <table id="functions-formatting-examples-table">
8734 <title><function>to_char</function> Examples</title>
8735 <tgroup cols="2">
8736 <thead>
8737 <row>
8738 <entry>Expression</entry>
8739 <entry>Result</entry>
8740 </row>
8741 </thead>
8742 <tbody>
8743 <row>
8744 <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8745 <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
8746 </row>
8747 <row>
8748 <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8749 <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
8750 </row>
8751 <row>
8752 <entry><literal>to_char(current_timestamp AT TIME ZONE
8753 'UTC', 'YYYY-MM-DD"T"HH24:MI:SS"Z"')</literal></entry>
8754 <entry><literal>'2022-12-06T05:39:18Z'</literal>,
8755 <acronym>ISO</acronym> 8601 extended format</entry>
8756 </row>
8757 <row>
8758 <entry><literal>to_char(-0.1, '99.99')</literal></entry>
8759 <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
8760 </row>
8761 <row>
8762 <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
8763 <entry><literal>'-.1'</literal></entry>
8764 </row>
8765 <row>
8766 <entry><literal>to_char(-0.1, 'FM90.99')</literal></entry>
8767 <entry><literal>'-0.1'</literal></entry>
8768 </row>
8769 <row>
8770 <entry><literal>to_char(0.1, '0.9')</literal></entry>
8771 <entry><literal>'&nbsp;0.1'</literal></entry>
8772 </row>
8773 <row>
8774 <entry><literal>to_char(12, '9990999.9')</literal></entry>
8775 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
8776 </row>
8777 <row>
8778 <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
8779 <entry><literal>'0012.'</literal></entry>
8780 </row>
8781 <row>
8782 <entry><literal>to_char(485, '999')</literal></entry>
8783 <entry><literal>'&nbsp;485'</literal></entry>
8784 </row>
8785 <row>
8786 <entry><literal>to_char(-485, '999')</literal></entry>
8787 <entry><literal>'-485'</literal></entry>
8788 </row>
8789 <row>
8790 <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
8791 <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
8792 </row>
8793 <row>
8794 <entry><literal>to_char(1485, '9,999')</literal></entry>
8795 <entry><literal>'&nbsp;1,485'</literal></entry>
8796 </row>
8797 <row>
8798 <entry><literal>to_char(1485, '9G999')</literal></entry>
8799 <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
8800 </row>
8801 <row>
8802 <entry><literal>to_char(148.5, '999.999')</literal></entry>
8803 <entry><literal>'&nbsp;148.500'</literal></entry>
8804 </row>
8805 <row>
8806 <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
8807 <entry><literal>'148.5'</literal></entry>
8808 </row>
8809 <row>
8810 <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
8811 <entry><literal>'148.500'</literal></entry>
8812 </row>
8813 <row>
8814 <entry><literal>to_char(148.5, '999D999')</literal></entry>
8815 <entry><literal>'&nbsp;148,500'</literal></entry>
8816 </row>
8817 <row>
8818 <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
8819 <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
8820 </row>
8821 <row>
8822 <entry><literal>to_char(-485, '999S')</literal></entry>
8823 <entry><literal>'485-'</literal></entry>
8824 </row>
8825 <row>
8826 <entry><literal>to_char(-485, '999MI')</literal></entry>
8827 <entry><literal>'485-'</literal></entry>
8828 </row>
8829 <row>
8830 <entry><literal>to_char(485, '999MI')</literal></entry>
8831 <entry><literal>'485&nbsp;'</literal></entry>
8832 </row>
8833 <row>
8834 <entry><literal>to_char(485, 'FM999MI')</literal></entry>
8835 <entry><literal>'485'</literal></entry>
8836 </row>
8837 <row>
8838 <entry><literal>to_char(485, 'PL999')</literal></entry>
8839 <entry><literal>'+485'</literal></entry>
8840 </row>
8841 <row>
8842 <entry><literal>to_char(485, 'SG999')</literal></entry>
8843 <entry><literal>'+485'</literal></entry>
8844 </row>
8845 <row>
8846 <entry><literal>to_char(-485, 'SG999')</literal></entry>
8847 <entry><literal>'-485'</literal></entry>
8848 </row>
8849 <row>
8850 <entry><literal>to_char(-485, '9SG99')</literal></entry>
8851 <entry><literal>'4-85'</literal></entry>
8852 </row>
8853 <row>
8854 <entry><literal>to_char(-485, '999PR')</literal></entry>
8855 <entry><literal>'&lt;485&gt;'</literal></entry>
8856 </row>
8857 <row>
8858 <entry><literal>to_char(485, 'L999')</literal></entry>
8859 <entry><literal>'DM&nbsp;485'</literal></entry>
8860 </row>
8861 <row>
8862 <entry><literal>to_char(485, 'RN')</literal></entry>
8863 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
8864 </row>
8865 <row>
8866 <entry><literal>to_char(485, 'FMRN')</literal></entry>
8867 <entry><literal>'CDLXXXV'</literal></entry>
8868 </row>
8869 <row>
8870 <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
8871 <entry><literal>'V'</literal></entry>
8872 </row>
8873 <row>
8874 <entry><literal>to_char(482, '999th')</literal></entry>
8875 <entry><literal>'&nbsp;482nd'</literal></entry>
8876 </row>
8877 <row>
8878 <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
8879 <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
8880 </row>
8881 <row>
8882 <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
8883 <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
8884 </row>
8885 <row>
8886 <entry><literal>to_char(12, '99V999')</literal></entry>
8887 <entry><literal>'&nbsp;12000'</literal></entry>
8888 </row>
8889 <row>
8890 <entry><literal>to_char(12.4, '99V999')</literal></entry>
8891 <entry><literal>'&nbsp;12400'</literal></entry>
8892 </row>
8893 <row>
8894 <entry><literal>to_char(12.45, '99V9')</literal></entry>
8895 <entry><literal>'&nbsp;125'</literal></entry>
8896 </row>
8897 <row>
8898 <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
8899 <entry><literal>' 4.86e-04'</literal></entry>
8900 </row>
8901 </tbody>
8902 </tgroup>
8903 </table>
8905 </sect1>
8908 <sect1 id="functions-datetime">
8909 <title>Date/Time Functions and Operators</title>
8911 <para>
8912 <xref linkend="functions-datetime-table"/> shows the available
8913 functions for date/time value processing, with details appearing in
8914 the following subsections. <xref
8915 linkend="operators-datetime-table"/> illustrates the behaviors of
8916 the basic arithmetic operators (<literal>+</literal>,
8917 <literal>*</literal>, etc.). For formatting functions, refer to
8918 <xref linkend="functions-formatting"/>. You should be familiar with
8919 the background information on date/time data types from <xref
8920 linkend="datatype-datetime"/>.
8921 </para>
8923 <para>
8924 In addition, the usual comparison operators shown in
8925 <xref linkend="functions-comparison-op-table"/> are available for the
8926 date/time types. Dates and timestamps (with or without time zone) are
8927 all comparable, while times (with or without time zone) and intervals
8928 can only be compared to other values of the same data type. When
8929 comparing a timestamp without time zone to a timestamp with time zone,
8930 the former value is assumed to be given in the time zone specified by
8931 the <xref linkend="guc-timezone"/> configuration parameter, and is
8932 rotated to UTC for comparison to the latter value (which is already
8933 in UTC internally). Similarly, a date value is assumed to represent
8934 midnight in the <varname>TimeZone</varname> zone when comparing it
8935 to a timestamp.
8936 </para>
8938 <para>
8939 All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
8940 inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
8941 with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
8942 For brevity, these variants are not shown separately. Also, the
8943 <literal>+</literal> and <literal>*</literal> operators come in commutative pairs (for
8944 example both <type>date</type> <literal>+</literal> <type>integer</type>
8945 and <type>integer</type> <literal>+</literal> <type>date</type>); we show
8946 only one of each such pair.
8947 </para>
8949 <table id="operators-datetime-table">
8950 <title>Date/Time Operators</title>
8952 <tgroup cols="1">
8953 <thead>
8954 <row>
8955 <entry role="func_table_entry"><para role="func_signature">
8956 Operator
8957 </para>
8958 <para>
8959 Description
8960 </para>
8961 <para>
8962 Example(s)
8963 </para></entry>
8964 </row>
8965 </thead>
8967 <tbody>
8968 <row>
8969 <entry role="func_table_entry"><para role="func_signature">
8970 <type>date</type> <literal>+</literal> <type>integer</type>
8971 <returnvalue>date</returnvalue>
8972 </para>
8973 <para>
8974 Add a number of days to a date
8975 </para>
8976 <para>
8977 <literal>date '2001-09-28' + 7</literal>
8978 <returnvalue>2001-10-05</returnvalue>
8979 </para></entry>
8980 </row>
8982 <row>
8983 <entry role="func_table_entry"><para role="func_signature">
8984 <type>date</type> <literal>+</literal> <type>interval</type>
8985 <returnvalue>timestamp</returnvalue>
8986 </para>
8987 <para>
8988 Add an interval to a date
8989 </para>
8990 <para>
8991 <literal>date '2001-09-28' + interval '1 hour'</literal>
8992 <returnvalue>2001-09-28 01:00:00</returnvalue>
8993 </para></entry>
8994 </row>
8996 <row>
8997 <entry role="func_table_entry"><para role="func_signature">
8998 <type>date</type> <literal>+</literal> <type>time</type>
8999 <returnvalue>timestamp</returnvalue>
9000 </para>
9001 <para>
9002 Add a time-of-day to a date
9003 </para>
9004 <para>
9005 <literal>date '2001-09-28' + time '03:00'</literal>
9006 <returnvalue>2001-09-28 03:00:00</returnvalue>
9007 </para></entry>
9008 </row>
9010 <row>
9011 <entry role="func_table_entry"><para role="func_signature">
9012 <type>interval</type> <literal>+</literal> <type>interval</type>
9013 <returnvalue>interval</returnvalue>
9014 </para>
9015 <para>
9016 Add intervals
9017 </para>
9018 <para>
9019 <literal>interval '1 day' + interval '1 hour'</literal>
9020 <returnvalue>1 day 01:00:00</returnvalue>
9021 </para></entry>
9022 </row>
9024 <row>
9025 <entry role="func_table_entry"><para role="func_signature">
9026 <type>timestamp</type> <literal>+</literal> <type>interval</type>
9027 <returnvalue>timestamp</returnvalue>
9028 </para>
9029 <para>
9030 Add an interval to a timestamp
9031 </para>
9032 <para>
9033 <literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal>
9034 <returnvalue>2001-09-29 00:00:00</returnvalue>
9035 </para></entry>
9036 </row>
9038 <row>
9039 <entry role="func_table_entry"><para role="func_signature">
9040 <type>time</type> <literal>+</literal> <type>interval</type>
9041 <returnvalue>time</returnvalue>
9042 </para>
9043 <para>
9044 Add an interval to a time
9045 </para>
9046 <para>
9047 <literal>time '01:00' + interval '3 hours'</literal>
9048 <returnvalue>04:00:00</returnvalue>
9049 </para></entry>
9050 </row>
9052 <row>
9053 <entry role="func_table_entry"><para role="func_signature">
9054 <literal>-</literal> <type>interval</type>
9055 <returnvalue>interval</returnvalue>
9056 </para>
9057 <para>
9058 Negate an interval
9059 </para>
9060 <para>
9061 <literal>- interval '23 hours'</literal>
9062 <returnvalue>-23:00:00</returnvalue>
9063 </para></entry>
9064 </row>
9066 <row>
9067 <entry role="func_table_entry"><para role="func_signature">
9068 <type>date</type> <literal>-</literal> <type>date</type>
9069 <returnvalue>integer</returnvalue>
9070 </para>
9071 <para>
9072 Subtract dates, producing the number of days elapsed
9073 </para>
9074 <para>
9075 <literal>date '2001-10-01' - date '2001-09-28'</literal>
9076 <returnvalue>3</returnvalue>
9077 </para></entry>
9078 </row>
9080 <row>
9081 <entry role="func_table_entry"><para role="func_signature">
9082 <type>date</type> <literal>-</literal> <type>integer</type>
9083 <returnvalue>date</returnvalue>
9084 </para>
9085 <para>
9086 Subtract a number of days from a date
9087 </para>
9088 <para>
9089 <literal>date '2001-10-01' - 7</literal>
9090 <returnvalue>2001-09-24</returnvalue>
9091 </para></entry>
9092 </row>
9094 <row>
9095 <entry role="func_table_entry"><para role="func_signature">
9096 <type>date</type> <literal>-</literal> <type>interval</type>
9097 <returnvalue>timestamp</returnvalue>
9098 </para>
9099 <para>
9100 Subtract an interval from a date
9101 </para>
9102 <para>
9103 <literal>date '2001-09-28' - interval '1 hour'</literal>
9104 <returnvalue>2001-09-27 23:00:00</returnvalue>
9105 </para></entry>
9106 </row>
9108 <row>
9109 <entry role="func_table_entry"><para role="func_signature">
9110 <type>time</type> <literal>-</literal> <type>time</type>
9111 <returnvalue>interval</returnvalue>
9112 </para>
9113 <para>
9114 Subtract times
9115 </para>
9116 <para>
9117 <literal>time '05:00' - time '03:00'</literal>
9118 <returnvalue>02:00:00</returnvalue>
9119 </para></entry>
9120 </row>
9122 <row>
9123 <entry role="func_table_entry"><para role="func_signature">
9124 <type>time</type> <literal>-</literal> <type>interval</type>
9125 <returnvalue>time</returnvalue>
9126 </para>
9127 <para>
9128 Subtract an interval from a time
9129 </para>
9130 <para>
9131 <literal>time '05:00' - interval '2 hours'</literal>
9132 <returnvalue>03:00:00</returnvalue>
9133 </para></entry>
9134 </row>
9136 <row>
9137 <entry role="func_table_entry"><para role="func_signature">
9138 <type>timestamp</type> <literal>-</literal> <type>interval</type>
9139 <returnvalue>timestamp</returnvalue>
9140 </para>
9141 <para>
9142 Subtract an interval from a timestamp
9143 </para>
9144 <para>
9145 <literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal>
9146 <returnvalue>2001-09-28 00:00:00</returnvalue>
9147 </para></entry>
9148 </row>
9150 <row>
9151 <entry role="func_table_entry"><para role="func_signature">
9152 <type>interval</type> <literal>-</literal> <type>interval</type>
9153 <returnvalue>interval</returnvalue>
9154 </para>
9155 <para>
9156 Subtract intervals
9157 </para>
9158 <para>
9159 <literal>interval '1 day' - interval '1 hour'</literal>
9160 <returnvalue>1 day -01:00:00</returnvalue>
9161 </para></entry>
9162 </row>
9164 <row>
9165 <entry role="func_table_entry"><para role="func_signature">
9166 <type>timestamp</type> <literal>-</literal> <type>timestamp</type>
9167 <returnvalue>interval</returnvalue>
9168 </para>
9169 <para>
9170 Subtract timestamps (converting 24-hour intervals into days,
9171 similarly to <function>justify_hours()</function>)
9172 </para>
9173 <para>
9174 <literal>timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00'</literal>
9175 <returnvalue>63 days 15:00:00</returnvalue>
9176 </para></entry>
9177 </row>
9179 <row>
9180 <entry role="func_table_entry"><para role="func_signature">
9181 <type>interval</type> <literal>*</literal> <type>double precision</type>
9182 <returnvalue>interval</returnvalue>
9183 </para>
9184 <para>
9185 Multiply an interval by a scalar
9186 </para>
9187 <para>
9188 <literal>interval '1 second' * 900</literal>
9189 <returnvalue>00:15:00</returnvalue>
9190 </para>
9191 <para>
9192 <literal>interval '1 day' * 21</literal>
9193 <returnvalue>21 days</returnvalue>
9194 </para>
9195 <para>
9196 <literal>interval '1 hour' * 3.5</literal>
9197 <returnvalue>03:30:00</returnvalue>
9198 </para></entry>
9199 </row>
9201 <row>
9202 <entry role="func_table_entry"><para role="func_signature">
9203 <type>interval</type> <literal>/</literal> <type>double precision</type>
9204 <returnvalue>interval</returnvalue>
9205 </para>
9206 <para>
9207 Divide an interval by a scalar
9208 </para>
9209 <para>
9210 <literal>interval '1 hour' / 1.5</literal>
9211 <returnvalue>00:40:00</returnvalue>
9212 </para></entry>
9213 </row>
9214 </tbody>
9215 </tgroup>
9216 </table>
9218 <table id="functions-datetime-table">
9219 <title>Date/Time Functions</title>
9220 <tgroup cols="1">
9221 <thead>
9222 <row>
9223 <entry role="func_table_entry"><para role="func_signature">
9224 Function
9225 </para>
9226 <para>
9227 Description
9228 </para>
9229 <para>
9230 Example(s)
9231 </para></entry>
9232 </row>
9233 </thead>
9235 <tbody>
9236 <row>
9237 <entry role="func_table_entry"><para role="func_signature">
9238 <indexterm>
9239 <primary>age</primary>
9240 </indexterm>
9241 <function>age</function> ( <type>timestamp</type>, <type>timestamp</type> )
9242 <returnvalue>interval</returnvalue>
9243 </para>
9244 <para>
9245 Subtract arguments, producing a <quote>symbolic</quote> result that
9246 uses years and months, rather than just days
9247 </para>
9248 <para>
9249 <literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal>
9250 <returnvalue>43 years 9 mons 27 days</returnvalue>
9251 </para></entry>
9252 </row>
9254 <row>
9255 <entry role="func_table_entry"><para role="func_signature">
9256 <function>age</function> ( <type>timestamp</type> )
9257 <returnvalue>interval</returnvalue>
9258 </para>
9259 <para>
9260 Subtract argument from <function>current_date</function> (at midnight)
9261 </para>
9262 <para>
9263 <literal>age(timestamp '1957-06-13')</literal>
9264 <returnvalue>62 years 6 mons 10 days</returnvalue>
9265 </para></entry>
9266 </row>
9268 <row>
9269 <entry role="func_table_entry"><para role="func_signature">
9270 <indexterm>
9271 <primary>clock_timestamp</primary>
9272 </indexterm>
9273 <function>clock_timestamp</function> ( )
9274 <returnvalue>timestamp with time zone</returnvalue>
9275 </para>
9276 <para>
9277 Current date and time (changes during statement execution);
9278 see <xref linkend="functions-datetime-current"/>
9279 </para>
9280 <para>
9281 <literal>clock_timestamp()</literal>
9282 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9283 </para></entry>
9284 </row>
9286 <row>
9287 <entry role="func_table_entry"><para role="func_signature">
9288 <indexterm>
9289 <primary>current_date</primary>
9290 </indexterm>
9291 <function>current_date</function>
9292 <returnvalue>date</returnvalue>
9293 </para>
9294 <para>
9295 Current date; see <xref linkend="functions-datetime-current"/>
9296 </para>
9297 <para>
9298 <literal>current_date</literal>
9299 <returnvalue>2019-12-23</returnvalue>
9300 </para></entry>
9301 </row>
9303 <row>
9304 <entry role="func_table_entry"><para role="func_signature">
9305 <indexterm>
9306 <primary>current_time</primary>
9307 </indexterm>
9308 <function>current_time</function>
9309 <returnvalue>time with time zone</returnvalue>
9310 </para>
9311 <para>
9312 Current time of day; see <xref linkend="functions-datetime-current"/>
9313 </para>
9314 <para>
9315 <literal>current_time</literal>
9316 <returnvalue>14:39:53.662522-05</returnvalue>
9317 </para></entry>
9318 </row>
9320 <row>
9321 <entry role="func_table_entry"><para role="func_signature">
9322 <function>current_time</function> ( <type>integer</type> )
9323 <returnvalue>time with time zone</returnvalue>
9324 </para>
9325 <para>
9326 Current time of day, with limited precision;
9327 see <xref linkend="functions-datetime-current"/>
9328 </para>
9329 <para>
9330 <literal>current_time(2)</literal>
9331 <returnvalue>14:39:53.66-05</returnvalue>
9332 </para></entry>
9333 </row>
9335 <row>
9336 <entry role="func_table_entry"><para role="func_signature">
9337 <indexterm>
9338 <primary>current_timestamp</primary>
9339 </indexterm>
9340 <function>current_timestamp</function>
9341 <returnvalue>timestamp with time zone</returnvalue>
9342 </para>
9343 <para>
9344 Current date and time (start of current transaction);
9345 see <xref linkend="functions-datetime-current"/>
9346 </para>
9347 <para>
9348 <literal>current_timestamp</literal>
9349 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9350 </para></entry>
9351 </row>
9353 <row>
9354 <entry role="func_table_entry"><para role="func_signature">
9355 <function>current_timestamp</function> ( <type>integer</type> )
9356 <returnvalue>timestamp with time zone</returnvalue>
9357 </para>
9358 <para>
9359 Current date and time (start of current transaction), with limited precision;
9360 see <xref linkend="functions-datetime-current"/>
9361 </para>
9362 <para>
9363 <literal>current_timestamp(0)</literal>
9364 <returnvalue>2019-12-23 14:39:53-05</returnvalue>
9365 </para></entry>
9366 </row>
9368 <row>
9369 <entry role="func_table_entry"><para role="func_signature">
9370 <indexterm>
9371 <primary>date_add</primary>
9372 </indexterm>
9373 <function>date_add</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
9374 <returnvalue>timestamp with time zone</returnvalue>
9375 </para>
9376 <para>
9377 Add an <type>interval</type> to a <type>timestamp with time
9378 zone</type>, computing times of day and daylight-savings adjustments
9379 according to the time zone named by the third argument, or the
9380 current <xref linkend="guc-timezone"/> setting if that is omitted.
9381 The form with two arguments is equivalent to the <type>timestamp with
9382 time zone</type> <literal>+</literal> <type>interval</type> operator.
9383 </para>
9384 <para>
9385 <literal>date_add('2021-10-31 00:00:00+02'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
9386 <returnvalue>2021-10-31 23:00:00+00</returnvalue>
9387 </para></entry>
9388 </row>
9390 <row>
9391 <entry role="func_table_entry"><para role="func_signature">
9392 <function>date_bin</function> ( <type>interval</type>, <type>timestamp</type>, <type>timestamp</type> )
9393 <returnvalue>timestamp</returnvalue>
9394 </para>
9395 <para>
9396 Bin input into specified interval aligned with specified origin; see <xref linkend="functions-datetime-bin"/>
9397 </para>
9398 <para>
9399 <literal>date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00')</literal>
9400 <returnvalue>2001-02-16 20:35:00</returnvalue>
9401 </para></entry>
9402 </row>
9404 <row>
9405 <entry role="func_table_entry"><para role="func_signature">
9406 <indexterm>
9407 <primary>date_part</primary>
9408 </indexterm>
9409 <function>date_part</function> ( <type>text</type>, <type>timestamp</type> )
9410 <returnvalue>double precision</returnvalue>
9411 </para>
9412 <para>
9413 Get timestamp subfield (equivalent to <function>extract</function>);
9414 see <xref linkend="functions-datetime-extract"/>
9415 </para>
9416 <para>
9417 <literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal>
9418 <returnvalue>20</returnvalue>
9419 </para></entry>
9420 </row>
9422 <row>
9423 <entry role="func_table_entry"><para role="func_signature">
9424 <function>date_part</function> ( <type>text</type>, <type>interval</type> )
9425 <returnvalue>double precision</returnvalue>
9426 </para>
9427 <para>
9428 Get interval subfield (equivalent to <function>extract</function>);
9429 see <xref linkend="functions-datetime-extract"/>
9430 </para>
9431 <para>
9432 <literal>date_part('month', interval '2 years 3 months')</literal>
9433 <returnvalue>3</returnvalue>
9434 </para></entry>
9435 </row>
9437 <row>
9438 <entry role="func_table_entry"><para role="func_signature">
9439 <indexterm>
9440 <primary>date_subtract</primary>
9441 </indexterm>
9442 <function>date_subtract</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
9443 <returnvalue>timestamp with time zone</returnvalue>
9444 </para>
9445 <para>
9446 Subtract an <type>interval</type> from a <type>timestamp with time
9447 zone</type>, computing times of day and daylight-savings adjustments
9448 according to the time zone named by the third argument, or the
9449 current <xref linkend="guc-timezone"/> setting if that is omitted.
9450 The form with two arguments is equivalent to the <type>timestamp with
9451 time zone</type> <literal>-</literal> <type>interval</type> operator.
9452 </para>
9453 <para>
9454 <literal>date_subtract('2021-11-01 00:00:00+01'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
9455 <returnvalue>2021-10-30 22:00:00+00</returnvalue>
9456 </para></entry>
9457 </row>
9459 <row>
9460 <entry role="func_table_entry"><para role="func_signature">
9461 <indexterm>
9462 <primary>date_trunc</primary>
9463 </indexterm>
9464 <function>date_trunc</function> ( <type>text</type>, <type>timestamp</type> )
9465 <returnvalue>timestamp</returnvalue>
9466 </para>
9467 <para>
9468 Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
9469 </para>
9470 <para>
9471 <literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal>
9472 <returnvalue>2001-02-16 20:00:00</returnvalue>
9473 </para></entry>
9474 </row>
9476 <row>
9477 <entry role="func_table_entry"><para role="func_signature">
9478 <function>date_trunc</function> ( <type>text</type>, <type>timestamp with time zone</type>, <type>text</type> )
9479 <returnvalue>timestamp with time zone</returnvalue>
9480 </para>
9481 <para>
9482 Truncate to specified precision in the specified time zone; see
9483 <xref linkend="functions-datetime-trunc"/>
9484 </para>
9485 <para>
9486 <literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal>
9487 <returnvalue>2001-02-16 13:00:00+00</returnvalue>
9488 </para></entry>
9489 </row>
9491 <row>
9492 <entry role="func_table_entry"><para role="func_signature">
9493 <function>date_trunc</function> ( <type>text</type>, <type>interval</type> )
9494 <returnvalue>interval</returnvalue>
9495 </para>
9496 <para>
9497 Truncate to specified precision; see
9498 <xref linkend="functions-datetime-trunc"/>
9499 </para>
9500 <para>
9501 <literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal>
9502 <returnvalue>2 days 03:00:00</returnvalue>
9503 </para></entry>
9504 </row>
9506 <row>
9507 <entry role="func_table_entry"><para role="func_signature">
9508 <indexterm>
9509 <primary>extract</primary>
9510 </indexterm>
9511 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> )
9512 <returnvalue>numeric</returnvalue>
9513 </para>
9514 <para>
9515 Get timestamp subfield; see <xref linkend="functions-datetime-extract"/>
9516 </para>
9517 <para>
9518 <literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal>
9519 <returnvalue>20</returnvalue>
9520 </para></entry>
9521 </row>
9523 <row>
9524 <entry role="func_table_entry"><para role="func_signature">
9525 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> )
9526 <returnvalue>numeric</returnvalue>
9527 </para>
9528 <para>
9529 Get interval subfield; see <xref linkend="functions-datetime-extract"/>
9530 </para>
9531 <para>
9532 <literal>extract(month from interval '2 years 3 months')</literal>
9533 <returnvalue>3</returnvalue>
9534 </para></entry>
9535 </row>
9537 <row>
9538 <entry role="func_table_entry"><para role="func_signature">
9539 <indexterm>
9540 <primary>isfinite</primary>
9541 </indexterm>
9542 <function>isfinite</function> ( <type>date</type> )
9543 <returnvalue>boolean</returnvalue>
9544 </para>
9545 <para>
9546 Test for finite date (not +/-infinity)
9547 </para>
9548 <para>
9549 <literal>isfinite(date '2001-02-16')</literal>
9550 <returnvalue>true</returnvalue>
9551 </para></entry>
9552 </row>
9554 <row>
9555 <entry role="func_table_entry"><para role="func_signature">
9556 <function>isfinite</function> ( <type>timestamp</type> )
9557 <returnvalue>boolean</returnvalue>
9558 </para>
9559 <para>
9560 Test for finite timestamp (not +/-infinity)
9561 </para>
9562 <para>
9563 <literal>isfinite(timestamp 'infinity')</literal>
9564 <returnvalue>false</returnvalue>
9565 </para></entry>
9566 </row>
9568 <row>
9569 <entry role="func_table_entry"><para role="func_signature">
9570 <function>isfinite</function> ( <type>interval</type> )
9571 <returnvalue>boolean</returnvalue>
9572 </para>
9573 <para>
9574 Test for finite interval (not +/-infinity)
9575 </para>
9576 <para>
9577 <literal>isfinite(interval '4 hours')</literal>
9578 <returnvalue>true</returnvalue>
9579 </para></entry>
9580 </row>
9582 <row>
9583 <entry role="func_table_entry"><para role="func_signature">
9584 <indexterm>
9585 <primary>justify_days</primary>
9586 </indexterm>
9587 <function>justify_days</function> ( <type>interval</type> )
9588 <returnvalue>interval</returnvalue>
9589 </para>
9590 <para>
9591 Adjust interval so 30-day time periods are represented as months
9592 </para>
9593 <para>
9594 <literal>justify_days(interval '35 days')</literal>
9595 <returnvalue>1 mon 5 days</returnvalue>
9596 </para></entry>
9597 </row>
9599 <row>
9600 <entry role="func_table_entry"><para role="func_signature">
9601 <indexterm>
9602 <primary>justify_hours</primary>
9603 </indexterm>
9604 <function>justify_hours</function> ( <type>interval</type> )
9605 <returnvalue>interval</returnvalue>
9606 </para>
9607 <para>
9608 Adjust interval so 24-hour time periods are represented as days
9609 </para>
9610 <para>
9611 <literal>justify_hours(interval '27 hours')</literal>
9612 <returnvalue>1 day 03:00:00</returnvalue>
9613 </para></entry>
9614 </row>
9616 <row>
9617 <entry role="func_table_entry"><para role="func_signature">
9618 <indexterm>
9619 <primary>justify_interval</primary>
9620 </indexterm>
9621 <function>justify_interval</function> ( <type>interval</type> )
9622 <returnvalue>interval</returnvalue>
9623 </para>
9624 <para>
9625 Adjust interval using <function>justify_days</function>
9626 and <function>justify_hours</function>, with additional sign
9627 adjustments
9628 </para>
9629 <para>
9630 <literal>justify_interval(interval '1 mon -1 hour')</literal>
9631 <returnvalue>29 days 23:00:00</returnvalue>
9632 </para></entry>
9633 </row>
9635 <row>
9636 <entry role="func_table_entry"><para role="func_signature">
9637 <indexterm>
9638 <primary>localtime</primary>
9639 </indexterm>
9640 <function>localtime</function>
9641 <returnvalue>time</returnvalue>
9642 </para>
9643 <para>
9644 Current time of day;
9645 see <xref linkend="functions-datetime-current"/>
9646 </para>
9647 <para>
9648 <literal>localtime</literal>
9649 <returnvalue>14:39:53.662522</returnvalue>
9650 </para></entry>
9651 </row>
9653 <row>
9654 <entry role="func_table_entry"><para role="func_signature">
9655 <function>localtime</function> ( <type>integer</type> )
9656 <returnvalue>time</returnvalue>
9657 </para>
9658 <para>
9659 Current time of day, with limited precision;
9660 see <xref linkend="functions-datetime-current"/>
9661 </para>
9662 <para>
9663 <literal>localtime(0)</literal>
9664 <returnvalue>14:39:53</returnvalue>
9665 </para></entry>
9666 </row>
9668 <row>
9669 <entry role="func_table_entry"><para role="func_signature">
9670 <indexterm>
9671 <primary>localtimestamp</primary>
9672 </indexterm>
9673 <function>localtimestamp</function>
9674 <returnvalue>timestamp</returnvalue>
9675 </para>
9676 <para>
9677 Current date and time (start of current transaction);
9678 see <xref linkend="functions-datetime-current"/>
9679 </para>
9680 <para>
9681 <literal>localtimestamp</literal>
9682 <returnvalue>2019-12-23 14:39:53.662522</returnvalue>
9683 </para></entry>
9684 </row>
9686 <row>
9687 <entry role="func_table_entry"><para role="func_signature">
9688 <function>localtimestamp</function> ( <type>integer</type> )
9689 <returnvalue>timestamp</returnvalue>
9690 </para>
9691 <para>
9692 Current date and time (start of current
9693 transaction), with limited precision;
9694 see <xref linkend="functions-datetime-current"/>
9695 </para>
9696 <para>
9697 <literal>localtimestamp(2)</literal>
9698 <returnvalue>2019-12-23 14:39:53.66</returnvalue>
9699 </para></entry>
9700 </row>
9702 <row>
9703 <entry role="func_table_entry"><para role="func_signature">
9704 <indexterm>
9705 <primary>make_date</primary>
9706 </indexterm>
9707 <function>make_date</function> ( <parameter>year</parameter> <type>int</type>,
9708 <parameter>month</parameter> <type>int</type>,
9709 <parameter>day</parameter> <type>int</type> )
9710 <returnvalue>date</returnvalue>
9711 </para>
9712 <para>
9713 Create date from year, month and day fields
9714 (negative years signify BC)
9715 </para>
9716 <para>
9717 <literal>make_date(2013, 7, 15)</literal>
9718 <returnvalue>2013-07-15</returnvalue>
9719 </para></entry>
9720 </row>
9722 <row>
9723 <entry role="func_table_entry"><para role="func_signature"><indexterm>
9724 <primary>make_interval</primary>
9725 </indexterm>
9726 <function>make_interval</function> ( <optional> <parameter>years</parameter> <type>int</type>
9727 <optional>, <parameter>months</parameter> <type>int</type>
9728 <optional>, <parameter>weeks</parameter> <type>int</type>
9729 <optional>, <parameter>days</parameter> <type>int</type>
9730 <optional>, <parameter>hours</parameter> <type>int</type>
9731 <optional>, <parameter>mins</parameter> <type>int</type>
9732 <optional>, <parameter>secs</parameter> <type>double precision</type>
9733 </optional></optional></optional></optional></optional></optional></optional> )
9734 <returnvalue>interval</returnvalue>
9735 </para>
9736 <para>
9737 Create interval from years, months, weeks, days, hours, minutes and
9738 seconds fields, each of which can default to zero
9739 </para>
9740 <para>
9741 <literal>make_interval(days =&gt; 10)</literal>
9742 <returnvalue>10 days</returnvalue>
9743 </para></entry>
9744 </row>
9746 <row>
9747 <entry role="func_table_entry"><para role="func_signature">
9748 <indexterm>
9749 <primary>make_time</primary>
9750 </indexterm>
9751 <function>make_time</function> ( <parameter>hour</parameter> <type>int</type>,
9752 <parameter>min</parameter> <type>int</type>,
9753 <parameter>sec</parameter> <type>double precision</type> )
9754 <returnvalue>time</returnvalue>
9755 </para>
9756 <para>
9757 Create time from hour, minute and seconds fields
9758 </para>
9759 <para>
9760 <literal>make_time(8, 15, 23.5)</literal>
9761 <returnvalue>08:15:23.5</returnvalue>
9762 </para></entry>
9763 </row>
9765 <row>
9766 <entry role="func_table_entry"><para role="func_signature">
9767 <indexterm>
9768 <primary>make_timestamp</primary>
9769 </indexterm>
9770 <function>make_timestamp</function> ( <parameter>year</parameter> <type>int</type>,
9771 <parameter>month</parameter> <type>int</type>,
9772 <parameter>day</parameter> <type>int</type>,
9773 <parameter>hour</parameter> <type>int</type>,
9774 <parameter>min</parameter> <type>int</type>,
9775 <parameter>sec</parameter> <type>double precision</type> )
9776 <returnvalue>timestamp</returnvalue>
9777 </para>
9778 <para>
9779 Create timestamp from year, month, day, hour, minute and seconds fields
9780 (negative years signify BC)
9781 </para>
9782 <para>
9783 <literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal>
9784 <returnvalue>2013-07-15 08:15:23.5</returnvalue>
9785 </para></entry>
9786 </row>
9788 <row>
9789 <entry role="func_table_entry"><para role="func_signature">
9790 <indexterm>
9791 <primary>make_timestamptz</primary>
9792 </indexterm>
9793 <function>make_timestamptz</function> ( <parameter>year</parameter> <type>int</type>,
9794 <parameter>month</parameter> <type>int</type>,
9795 <parameter>day</parameter> <type>int</type>,
9796 <parameter>hour</parameter> <type>int</type>,
9797 <parameter>min</parameter> <type>int</type>,
9798 <parameter>sec</parameter> <type>double precision</type>
9799 <optional>, <parameter>timezone</parameter> <type>text</type> </optional> )
9800 <returnvalue>timestamp with time zone</returnvalue>
9801 </para>
9802 <para>
9803 Create timestamp with time zone from year, month, day, hour, minute
9804 and seconds fields (negative years signify BC).
9805 If <parameter>timezone</parameter> is not
9806 specified, the current time zone is used; the examples assume the
9807 session time zone is <literal>Europe/London</literal>
9808 </para>
9809 <para>
9810 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal>
9811 <returnvalue>2013-07-15 08:15:23.5+01</returnvalue>
9812 </para>
9813 <para>
9814 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')</literal>
9815 <returnvalue>2013-07-15 13:15:23.5+01</returnvalue>
9816 </para></entry>
9817 </row>
9819 <row>
9820 <entry role="func_table_entry"><para role="func_signature">
9821 <indexterm>
9822 <primary>now</primary>
9823 </indexterm>
9824 <function>now</function> ( )
9825 <returnvalue>timestamp with time zone</returnvalue>
9826 </para>
9827 <para>
9828 Current date and time (start of current transaction);
9829 see <xref linkend="functions-datetime-current"/>
9830 </para>
9831 <para>
9832 <literal>now()</literal>
9833 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9834 </para></entry>
9835 </row>
9837 <row>
9838 <entry role="func_table_entry"><para role="func_signature">
9839 <indexterm>
9840 <primary>statement_timestamp</primary>
9841 </indexterm>
9842 <function>statement_timestamp</function> ( )
9843 <returnvalue>timestamp with time zone</returnvalue>
9844 </para>
9845 <para>
9846 Current date and time (start of current statement);
9847 see <xref linkend="functions-datetime-current"/>
9848 </para>
9849 <para>
9850 <literal>statement_timestamp()</literal>
9851 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9852 </para></entry>
9853 </row>
9855 <row>
9856 <entry role="func_table_entry"><para role="func_signature">
9857 <indexterm>
9858 <primary>timeofday</primary>
9859 </indexterm>
9860 <function>timeofday</function> ( )
9861 <returnvalue>text</returnvalue>
9862 </para>
9863 <para>
9864 Current date and time
9865 (like <function>clock_timestamp</function>, but as a <type>text</type> string);
9866 see <xref linkend="functions-datetime-current"/>
9867 </para>
9868 <para>
9869 <literal>timeofday()</literal>
9870 <returnvalue>Mon Dec 23 14:39:53.662522 2019 EST</returnvalue>
9871 </para></entry>
9872 </row>
9874 <row>
9875 <entry role="func_table_entry"><para role="func_signature">
9876 <indexterm>
9877 <primary>transaction_timestamp</primary>
9878 </indexterm>
9879 <function>transaction_timestamp</function> ( )
9880 <returnvalue>timestamp with time zone</returnvalue>
9881 </para>
9882 <para>
9883 Current date and time (start of current transaction);
9884 see <xref linkend="functions-datetime-current"/>
9885 </para>
9886 <para>
9887 <literal>transaction_timestamp()</literal>
9888 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9889 </para></entry>
9890 </row>
9892 <row>
9893 <entry role="func_table_entry"><para role="func_signature">
9894 <indexterm>
9895 <primary>to_timestamp</primary>
9896 </indexterm>
9897 <function>to_timestamp</function> ( <type>double precision</type> )
9898 <returnvalue>timestamp with time zone</returnvalue>
9899 </para>
9900 <para>
9901 Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
9902 timestamp with time zone
9903 </para>
9904 <para>
9905 <literal>to_timestamp(1284352323)</literal>
9906 <returnvalue>2010-09-13 04:32:03+00</returnvalue>
9907 </para></entry>
9908 </row>
9909 </tbody>
9910 </tgroup>
9911 </table>
9913 <para>
9914 <indexterm>
9915 <primary>OVERLAPS</primary>
9916 </indexterm>
9917 In addition to these functions, the SQL <literal>OVERLAPS</literal> operator is
9918 supported:
9919 <synopsis>
9920 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
9921 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
9922 </synopsis>
9923 This expression yields true when two time periods (defined by their
9924 endpoints) overlap, false when they do not overlap. The endpoints
9925 can be specified as pairs of dates, times, or time stamps; or as
9926 a date, time, or time stamp followed by an interval. When a pair
9927 of values is provided, either the start or the end can be written
9928 first; <literal>OVERLAPS</literal> automatically takes the earlier value
9929 of the pair as the start. Each time period is considered to
9930 represent the half-open interval <replaceable>start</replaceable> <literal>&lt;=</literal>
9931 <replaceable>time</replaceable> <literal>&lt;</literal> <replaceable>end</replaceable>, unless
9932 <replaceable>start</replaceable> and <replaceable>end</replaceable> are equal in which case it
9933 represents that single time instant. This means for instance that two
9934 time periods with only an endpoint in common do not overlap.
9935 </para>
9937 <screen>
9938 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
9939 (DATE '2001-10-30', DATE '2002-10-30');
9940 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
9941 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
9942 (DATE '2001-10-30', DATE '2002-10-30');
9943 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
9944 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
9945 (DATE '2001-10-30', DATE '2001-10-31');
9946 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
9947 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
9948 (DATE '2001-10-30', DATE '2001-10-31');
9949 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
9950 </screen>
9952 <para>
9953 When adding an <type>interval</type> value to (or subtracting an
9954 <type>interval</type> value from) a <type>timestamp</type>
9955 or <type>timestamp with time zone</type> value, the months, days, and
9956 microseconds fields of the <type>interval</type> value are handled in turn.
9957 First, a nonzero months field advances or decrements the date of the
9958 timestamp by the indicated number of months, keeping the day of month the
9959 same unless it would be past the end of the new month, in which case the
9960 last day of that month is used. (For example, March 31 plus 1 month
9961 becomes April 30, but March 31 plus 2 months becomes May 31.)
9962 Then the days field advances or decrements the date of the timestamp by
9963 the indicated number of days. In both these steps the local time of day
9964 is kept the same. Finally, if there is a nonzero microseconds field, it
9965 is added or subtracted literally.
9966 When doing arithmetic on a <type>timestamp with time zone</type> value in
9967 a time zone that recognizes DST, this means that adding or subtracting
9968 (say) <literal>interval '1 day'</literal> does not necessarily have the
9969 same result as adding or subtracting <literal>interval '24
9970 hours'</literal>.
9971 For example, with the session time zone set
9972 to <literal>America/Denver</literal>:
9973 <screen>
9974 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day';
9975 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 12:00:00-06</computeroutput>
9976 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours';
9977 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 13:00:00-06</computeroutput>
9978 </screen>
9979 This happens because an hour was skipped due to a change in daylight saving
9980 time at <literal>2005-04-03 02:00:00</literal> in time zone
9981 <literal>America/Denver</literal>.
9982 </para>
9984 <para>
9985 Note there can be ambiguity in the <literal>months</literal> field returned by
9986 <function>age</function> because different months have different numbers of
9987 days. <productname>PostgreSQL</productname>'s approach uses the month from the
9988 earlier of the two dates when calculating partial months. For example,
9989 <literal>age('2004-06-01', '2004-04-30')</literal> uses April to yield
9990 <literal>1 mon 1 day</literal>, while using May would yield <literal>1 mon 2
9991 days</literal> because May has 31 days, while April has only 30.
9992 </para>
9994 <para>
9995 Subtraction of dates and timestamps can also be complex. One conceptually
9996 simple way to perform subtraction is to convert each value to a number
9997 of seconds using <literal>EXTRACT(EPOCH FROM ...)</literal>, then subtract the
9998 results; this produces the
9999 number of <emphasis>seconds</emphasis> between the two values. This will adjust
10000 for the number of days in each month, timezone changes, and daylight
10001 saving time adjustments. Subtraction of date or timestamp
10002 values with the <quote><literal>-</literal></quote> operator
10003 returns the number of days (24-hours) and hours/minutes/seconds
10004 between the values, making the same adjustments. The <function>age</function>
10005 function returns years, months, days, and hours/minutes/seconds,
10006 performing field-by-field subtraction and then adjusting for negative
10007 field values. The following queries illustrate the differences in these
10008 approaches. The sample results were produced with <literal>timezone
10009 = 'US/Eastern'</literal>; there is a daylight saving time change between the
10010 two dates used:
10011 </para>
10013 <screen>
10014 SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
10015 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
10016 <lineannotation>Result: </lineannotation><computeroutput>10537200.000000</computeroutput>
10017 SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
10018 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
10019 / 60 / 60 / 24;
10020 <lineannotation>Result: </lineannotation><computeroutput>121.9583333333333333</computeroutput>
10021 SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
10022 <lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
10023 SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
10024 <lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
10025 </screen>
10027 <sect2 id="functions-datetime-extract">
10028 <title><function>EXTRACT</function>, <function>date_part</function></title>
10030 <indexterm>
10031 <primary>date_part</primary>
10032 </indexterm>
10033 <indexterm>
10034 <primary>extract</primary>
10035 </indexterm>
10037 <synopsis>
10038 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
10039 </synopsis>
10041 <para>
10042 The <function>extract</function> function retrieves subfields
10043 such as year or hour from date/time values.
10044 <replaceable>source</replaceable> must be a value expression of
10045 type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
10046 (Expressions of type <type>date</type> are
10047 cast to <type>timestamp</type> and can therefore be used as
10048 well.) <replaceable>field</replaceable> is an identifier or
10049 string that selects what field to extract from the source value.
10050 The <function>extract</function> function returns values of type
10051 <type>numeric</type>.
10052 The following are valid field names:
10054 <!-- alphabetical -->
10055 <variablelist>
10056 <varlistentry>
10057 <term><literal>century</literal></term>
10058 <listitem>
10059 <para>
10060 The century
10061 </para>
10063 <screen>
10064 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
10065 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10066 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
10067 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
10068 </screen>
10070 <para>
10071 The first century starts at 0001-01-01 00:00:00 AD, although
10072 they did not know it at the time. This definition applies to all
10073 Gregorian calendar countries. There is no century number 0,
10074 you go from -1 century to 1 century.
10076 If you disagree with this, please write your complaint to:
10077 Pope, Cathedral Saint-Peter of Roma, Vatican.
10078 </para>
10079 </listitem>
10080 </varlistentry>
10082 <varlistentry>
10083 <term><literal>day</literal></term>
10084 <listitem>
10085 <para>
10086 For <type>timestamp</type> values, the day (of the month) field
10087 (1&ndash;31) ; for <type>interval</type> values, the number of days
10088 </para>
10090 <screen>
10091 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
10092 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
10094 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
10095 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
10096 </screen>
10098 </listitem>
10099 </varlistentry>
10101 <varlistentry>
10102 <term><literal>decade</literal></term>
10103 <listitem>
10104 <para>
10105 The year field divided by 10
10106 </para>
10108 <screen>
10109 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
10110 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
10111 </screen>
10112 </listitem>
10113 </varlistentry>
10115 <varlistentry>
10116 <term><literal>dow</literal></term>
10117 <listitem>
10118 <para>
10119 The day of the week as Sunday (<literal>0</literal>) to
10120 Saturday (<literal>6</literal>)
10121 </para>
10123 <screen>
10124 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
10125 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
10126 </screen>
10127 <para>
10128 Note that <function>extract</function>'s day of the week numbering
10129 differs from that of the <function>to_char(...,
10130 'D')</function> function.
10131 </para>
10133 </listitem>
10134 </varlistentry>
10136 <varlistentry>
10137 <term><literal>doy</literal></term>
10138 <listitem>
10139 <para>
10140 The day of the year (1&ndash;365/366)
10141 </para>
10143 <screen>
10144 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
10145 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
10146 </screen>
10147 </listitem>
10148 </varlistentry>
10150 <varlistentry>
10151 <term><literal>epoch</literal></term>
10152 <listitem>
10153 <para>
10154 For <type>timestamp with time zone</type> values, the
10155 number of seconds since 1970-01-01 00:00:00 UTC (negative for
10156 timestamps before that);
10157 for <type>date</type> and <type>timestamp</type> values, the
10158 nominal number of seconds since 1970-01-01 00:00:00,
10159 without regard to timezone or daylight-savings rules;
10160 for <type>interval</type> values, the total number
10161 of seconds in the interval
10162 </para>
10164 <screen>
10165 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
10166 <lineannotation>Result: </lineannotation><computeroutput>982384720.120000</computeroutput>
10168 SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12');
10169 <lineannotation>Result: </lineannotation><computeroutput>982355920.120000</computeroutput>
10171 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
10172 <lineannotation>Result: </lineannotation><computeroutput>442800.000000</computeroutput>
10173 </screen>
10175 <para>
10176 You can convert an epoch value back to a <type>timestamp with time zone</type>
10177 with <function>to_timestamp</function>:
10178 </para>
10179 <screen>
10180 SELECT to_timestamp(982384720.12);
10181 <lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput>
10182 </screen>
10184 <para>
10185 Beware that applying <function>to_timestamp</function> to an epoch
10186 extracted from a <type>date</type> or <type>timestamp</type> value
10187 could produce a misleading result: the result will effectively
10188 assume that the original value had been given in UTC, which might
10189 not be the case.
10190 </para>
10191 </listitem>
10192 </varlistentry>
10194 <varlistentry>
10195 <term><literal>hour</literal></term>
10196 <listitem>
10197 <para>
10198 The hour field (0&ndash;23)
10199 </para>
10201 <screen>
10202 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
10203 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10204 </screen>
10205 </listitem>
10206 </varlistentry>
10208 <varlistentry>
10209 <term><literal>isodow</literal></term>
10210 <listitem>
10211 <para>
10212 The day of the week as Monday (<literal>1</literal>) to
10213 Sunday (<literal>7</literal>)
10214 </para>
10216 <screen>
10217 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
10218 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10219 </screen>
10220 <para>
10221 This is identical to <literal>dow</literal> except for Sunday. This
10222 matches the <acronym>ISO</acronym> 8601 day of the week numbering.
10223 </para>
10225 </listitem>
10226 </varlistentry>
10228 <varlistentry>
10229 <term><literal>isoyear</literal></term>
10230 <listitem>
10231 <para>
10232 The <acronym>ISO</acronym> 8601 week-numbering year that the date
10233 falls in (not applicable to intervals)
10234 </para>
10236 <screen>
10237 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
10238 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
10239 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
10240 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
10241 </screen>
10243 <para>
10244 Each <acronym>ISO</acronym> 8601 week-numbering year begins with the
10245 Monday of the week containing the 4th of January, so in early
10246 January or late December the <acronym>ISO</acronym> year may be
10247 different from the Gregorian year. See the <literal>week</literal>
10248 field for more information.
10249 </para>
10250 <para>
10251 This field is not available in PostgreSQL releases prior to 8.3.
10252 </para>
10253 </listitem>
10254 </varlistentry>
10256 <varlistentry>
10257 <term><literal>julian</literal></term>
10258 <listitem>
10259 <para>
10260 The <firstterm>Julian Date</firstterm> corresponding to the
10261 date or timestamp (not applicable to intervals). Timestamps
10262 that are not local midnight result in a fractional value. See
10263 <xref linkend="datetime-julian-dates"/> for more information.
10264 </para>
10266 <screen>
10267 SELECT EXTRACT(JULIAN FROM DATE '2006-01-01');
10268 <lineannotation>Result: </lineannotation><computeroutput>2453737</computeroutput>
10269 SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00');
10270 <lineannotation>Result: </lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
10271 </screen>
10272 </listitem>
10273 </varlistentry>
10275 <varlistentry>
10276 <term><literal>microseconds</literal></term>
10277 <listitem>
10278 <para>
10279 The seconds field, including fractional parts, multiplied by 1
10280 000 000; note that this includes full seconds
10281 </para>
10283 <screen>
10284 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
10285 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
10286 </screen>
10287 </listitem>
10288 </varlistentry>
10290 <varlistentry>
10291 <term><literal>millennium</literal></term>
10292 <listitem>
10293 <para>
10294 The millennium
10295 </para>
10297 <screen>
10298 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
10299 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10300 </screen>
10302 <para>
10303 Years in the 1900s are in the second millennium.
10304 The third millennium started January 1, 2001.
10305 </para>
10306 </listitem>
10307 </varlistentry>
10309 <varlistentry>
10310 <term><literal>milliseconds</literal></term>
10311 <listitem>
10312 <para>
10313 The seconds field, including fractional parts, multiplied by
10314 1000. Note that this includes full seconds.
10315 </para>
10317 <screen>
10318 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
10319 <lineannotation>Result: </lineannotation><computeroutput>28500.000</computeroutput>
10320 </screen>
10321 </listitem>
10322 </varlistentry>
10324 <varlistentry>
10325 <term><literal>minute</literal></term>
10326 <listitem>
10327 <para>
10328 The minutes field (0&ndash;59)
10329 </para>
10331 <screen>
10332 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
10333 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
10334 </screen>
10335 </listitem>
10336 </varlistentry>
10338 <varlistentry>
10339 <term><literal>month</literal></term>
10340 <listitem>
10341 <para>
10342 For <type>timestamp</type> values, the number of the month
10343 within the year (1&ndash;12) ; for <type>interval</type> values,
10344 the number of months, modulo 12 (0&ndash;11)
10345 </para>
10347 <screen>
10348 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
10349 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
10351 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
10352 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10354 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
10355 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10356 </screen>
10357 </listitem>
10358 </varlistentry>
10360 <varlistentry>
10361 <term><literal>quarter</literal></term>
10362 <listitem>
10363 <para>
10364 The quarter of the year (1&ndash;4) that the date is in
10365 </para>
10367 <screen>
10368 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
10369 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10370 </screen>
10371 </listitem>
10372 </varlistentry>
10374 <varlistentry>
10375 <term><literal>second</literal></term>
10376 <listitem>
10377 <para>
10378 The seconds field, including any fractional seconds
10379 </para>
10381 <screen>
10382 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
10383 <lineannotation>Result: </lineannotation><computeroutput>40.000000</computeroutput>
10385 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
10386 <lineannotation>Result: </lineannotation><computeroutput>28.500000</computeroutput>
10387 </screen>
10388 </listitem>
10389 </varlistentry>
10390 <varlistentry>
10391 <term><literal>timezone</literal></term>
10392 <listitem>
10393 <para>
10394 The time zone offset from UTC, measured in seconds. Positive values
10395 correspond to time zones east of UTC, negative values to
10396 zones west of UTC. (Technically,
10397 <productname>PostgreSQL</productname> does not use UTC because
10398 leap seconds are not handled.)
10399 </para>
10400 </listitem>
10401 </varlistentry>
10403 <varlistentry>
10404 <term><literal>timezone_hour</literal></term>
10405 <listitem>
10406 <para>
10407 The hour component of the time zone offset
10408 </para>
10409 </listitem>
10410 </varlistentry>
10412 <varlistentry>
10413 <term><literal>timezone_minute</literal></term>
10414 <listitem>
10415 <para>
10416 The minute component of the time zone offset
10417 </para>
10418 </listitem>
10419 </varlistentry>
10421 <varlistentry>
10422 <term><literal>week</literal></term>
10423 <listitem>
10424 <para>
10425 The number of the <acronym>ISO</acronym> 8601 week-numbering week of
10426 the year. By definition, ISO weeks start on Mondays and the first
10427 week of a year contains January 4 of that year. In other words, the
10428 first Thursday of a year is in week 1 of that year.
10429 </para>
10430 <para>
10431 In the ISO week-numbering system, it is possible for early-January
10432 dates to be part of the 52nd or 53rd week of the previous year, and for
10433 late-December dates to be part of the first week of the next year.
10434 For example, <literal>2005-01-01</literal> is part of the 53rd week of year
10435 2004, and <literal>2006-01-01</literal> is part of the 52nd week of year
10436 2005, while <literal>2012-12-31</literal> is part of the first week of 2013.
10437 It's recommended to use the <literal>isoyear</literal> field together with
10438 <literal>week</literal> to get consistent results.
10439 </para>
10441 <screen>
10442 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
10443 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10444 </screen>
10445 </listitem>
10446 </varlistentry>
10448 <varlistentry>
10449 <term><literal>year</literal></term>
10450 <listitem>
10451 <para>
10452 The year field. Keep in mind there is no <literal>0 AD</literal>, so subtracting
10453 <literal>BC</literal> years from <literal>AD</literal> years should be done with care.
10454 </para>
10456 <screen>
10457 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
10458 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
10459 </screen>
10460 </listitem>
10461 </varlistentry>
10463 </variablelist>
10464 </para>
10466 <note>
10467 <para>
10468 When the input value is +/-Infinity, <function>extract</function> returns
10469 +/-Infinity for monotonically-increasing fields (<literal>epoch</literal>,
10470 <literal>julian</literal>, <literal>year</literal>, <literal>isoyear</literal>,
10471 <literal>decade</literal>, <literal>century</literal>, and <literal>millennium</literal>
10472 for <type>timestamp</type> inputs; <literal>epoch</literal>, <literal>hour</literal>,
10473 <literal>day</literal>, <literal>year</literal>, <literal>decade</literal>,
10474 <literal>century</literal>, and <literal>millennium</literal> for
10475 <type>interval</type> inputs).
10476 For other fields, NULL is returned. <productname>PostgreSQL</productname>
10477 versions before 9.6 returned zero for all cases of infinite input.
10478 </para>
10479 </note>
10481 <para>
10482 The <function>extract</function> function is primarily intended
10483 for computational processing. For formatting date/time values for
10484 display, see <xref linkend="functions-formatting"/>.
10485 </para>
10487 <para>
10488 The <function>date_part</function> function is modeled on the traditional
10489 <productname>Ingres</productname> equivalent to the
10490 <acronym>SQL</acronym>-standard function <function>extract</function>:
10491 <synopsis>
10492 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
10493 </synopsis>
10494 Note that here the <replaceable>field</replaceable> parameter needs to
10495 be a string value, not a name. The valid field names for
10496 <function>date_part</function> are the same as for
10497 <function>extract</function>.
10498 For historical reasons, the <function>date_part</function> function
10499 returns values of type <type>double precision</type>. This can result in
10500 a loss of precision in certain uses. Using <function>extract</function>
10501 is recommended instead.
10502 </para>
10504 <screen>
10505 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
10506 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
10508 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
10509 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
10510 </screen>
10512 </sect2>
10514 <sect2 id="functions-datetime-trunc">
10515 <title><function>date_trunc</function></title>
10517 <indexterm>
10518 <primary>date_trunc</primary>
10519 </indexterm>
10521 <para>
10522 The function <function>date_trunc</function> is conceptually
10523 similar to the <function>trunc</function> function for numbers.
10524 </para>
10526 <para>
10527 <synopsis>
10528 date_trunc(<replaceable>field</replaceable>, <replaceable>source</replaceable> [, <replaceable>time_zone</replaceable> ])
10529 </synopsis>
10530 <replaceable>source</replaceable> is a value expression of type
10531 <type>timestamp</type>, <type>timestamp with time zone</type>,
10532 or <type>interval</type>.
10533 (Values of type <type>date</type> and
10534 <type>time</type> are cast automatically to <type>timestamp</type> or
10535 <type>interval</type>, respectively.)
10536 <replaceable>field</replaceable> selects to which precision to
10537 truncate the input value. The return value is likewise of type
10538 <type>timestamp</type>, <type>timestamp with time zone</type>,
10539 or <type>interval</type>,
10540 and it has all fields that are less significant than the
10541 selected one set to zero (or one, for day and month).
10542 </para>
10544 <para>
10545 Valid values for <replaceable>field</replaceable> are:
10546 <simplelist>
10547 <member><literal>microseconds</literal></member>
10548 <member><literal>milliseconds</literal></member>
10549 <member><literal>second</literal></member>
10550 <member><literal>minute</literal></member>
10551 <member><literal>hour</literal></member>
10552 <member><literal>day</literal></member>
10553 <member><literal>week</literal></member>
10554 <member><literal>month</literal></member>
10555 <member><literal>quarter</literal></member>
10556 <member><literal>year</literal></member>
10557 <member><literal>decade</literal></member>
10558 <member><literal>century</literal></member>
10559 <member><literal>millennium</literal></member>
10560 </simplelist>
10561 </para>
10563 <para>
10564 When the input value is of type <type>timestamp with time zone</type>,
10565 the truncation is performed with respect to a particular time zone;
10566 for example, truncation to <literal>day</literal> produces a value that
10567 is midnight in that zone. By default, truncation is done with respect
10568 to the current <xref linkend="guc-timezone"/> setting, but the
10569 optional <replaceable>time_zone</replaceable> argument can be provided
10570 to specify a different time zone. The time zone name can be specified
10571 in any of the ways described in <xref linkend="datatype-timezones"/>.
10572 </para>
10574 <para>
10575 A time zone cannot be specified when processing <type>timestamp without
10576 time zone</type> or <type>interval</type> inputs. These are always
10577 taken at face value.
10578 </para>
10580 <para>
10581 Examples (assuming the local time zone is <literal>America/New_York</literal>):
10582 <screen>
10583 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
10584 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
10586 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
10587 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
10589 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
10590 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput>
10592 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
10593 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput>
10595 SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
10596 <lineannotation>Result: </lineannotation><computeroutput>3 days 02:00:00</computeroutput>
10597 </screen>
10598 </para>
10599 </sect2>
10601 <sect2 id="functions-datetime-bin">
10602 <title><function>date_bin</function></title>
10604 <indexterm>
10605 <primary>date_bin</primary>
10606 </indexterm>
10608 <para>
10609 The function <function>date_bin</function> <quote>bins</quote> the input
10610 timestamp into the specified interval (the <firstterm>stride</firstterm>)
10611 aligned with a specified origin.
10612 </para>
10614 <para>
10615 <synopsis>
10616 date_bin(<replaceable>stride</replaceable>, <replaceable>source</replaceable>, <replaceable>origin</replaceable>)
10617 </synopsis>
10618 <replaceable>source</replaceable> is a value expression of type
10619 <type>timestamp</type> or <type>timestamp with time zone</type>. (Values
10620 of type <type>date</type> are cast automatically to
10621 <type>timestamp</type>.) <replaceable>stride</replaceable> is a value
10622 expression of type <type>interval</type>. The return value is likewise
10623 of type <type>timestamp</type> or <type>timestamp with time zone</type>,
10624 and it marks the beginning of the bin into which the
10625 <replaceable>source</replaceable> is placed.
10626 </para>
10628 <para>
10629 Examples:
10630 <screen>
10631 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01');
10632 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:30:00</computeroutput>
10634 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30');
10635 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:32:30</computeroutput>
10636 </screen>
10637 </para>
10639 <para>
10640 In the case of full units (1 minute, 1 hour, etc.), it gives the same result as
10641 the analogous <function>date_trunc</function> call, but the difference is
10642 that <function>date_bin</function> can truncate to an arbitrary interval.
10643 </para>
10645 <para>
10646 The <parameter>stride</parameter> interval must be greater than zero and
10647 cannot contain units of month or larger.
10648 </para>
10649 </sect2>
10651 <sect2 id="functions-datetime-zoneconvert">
10652 <title><literal>AT TIME ZONE and AT LOCAL</literal></title>
10654 <indexterm>
10655 <primary>time zone</primary>
10656 <secondary>conversion</secondary>
10657 </indexterm>
10659 <indexterm>
10660 <primary>AT TIME ZONE</primary>
10661 </indexterm>
10663 <indexterm>
10664 <primary>AT LOCAL</primary>
10665 </indexterm>
10667 <para>
10668 The <literal>AT TIME ZONE</literal> operator converts time
10669 stamp <emphasis>without</emphasis> time zone to/from
10670 time stamp <emphasis>with</emphasis> time zone, and
10671 <type>time with time zone</type> values to different time
10672 zones. <xref linkend="functions-datetime-zoneconvert-table"/> shows its
10673 variants.
10674 </para>
10676 <table id="functions-datetime-zoneconvert-table">
10677 <title><literal>AT TIME ZONE</literal> and <literal>AT LOCAL</literal> Variants</title>
10678 <tgroup cols="1">
10679 <thead>
10680 <row>
10681 <entry role="func_table_entry"><para role="func_signature">
10682 Operator
10683 </para>
10684 <para>
10685 Description
10686 </para>
10687 <para>
10688 Example(s)
10689 </para></entry>
10690 </row>
10691 </thead>
10693 <tbody>
10694 <row>
10695 <entry role="func_table_entry"><para role="func_signature">
10696 <type>timestamp without time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10697 <returnvalue>timestamp with time zone</returnvalue>
10698 </para>
10699 <para>
10700 Converts given time stamp <emphasis>without</emphasis> time zone to
10701 time stamp <emphasis>with</emphasis> time zone, assuming the given
10702 value is in the named time zone.
10703 </para>
10704 <para>
10705 <literal>timestamp '2001-02-16 20:38:40' at time zone 'America/Denver'</literal>
10706 <returnvalue>2001-02-17 03:38:40+00</returnvalue>
10707 </para></entry>
10708 </row>
10710 <row>
10711 <entry role="func_table_entry"><para role="func_signature">
10712 <type>timestamp without time zone</type> <literal>AT LOCAL</literal>
10713 <returnvalue>timestamp with time zone</returnvalue>
10714 </para>
10715 <para>
10716 Converts given time stamp <emphasis>without</emphasis> time zone to
10717 time stamp <emphasis>with</emphasis> the session's
10718 <varname>TimeZone</varname> value as time zone.
10719 </para>
10720 <para>
10721 <literal>timestamp '2001-02-16 20:38:40' at local</literal>
10722 <returnvalue>2001-02-17 03:38:40+00</returnvalue>
10723 </para></entry>
10724 </row>
10726 <row>
10727 <entry role="func_table_entry"><para role="func_signature">
10728 <type>timestamp with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10729 <returnvalue>timestamp without time zone</returnvalue>
10730 </para>
10731 <para>
10732 Converts given time stamp <emphasis>with</emphasis> time zone to
10733 time stamp <emphasis>without</emphasis> time zone, as the time would
10734 appear in that zone.
10735 </para>
10736 <para>
10737 <literal>timestamp with time zone '2001-02-16 20:38:40-05' at time zone 'America/Denver'</literal>
10738 <returnvalue>2001-02-16 18:38:40</returnvalue>
10739 </para></entry>
10740 </row>
10742 <row>
10743 <entry role="func_table_entry"><para role="func_signature">
10744 <type>timestamp with time zone</type> <literal>AT LOCAL</literal>
10745 <returnvalue>timestamp without time zone</returnvalue>
10746 </para>
10747 <para>
10748 Converts given time stamp <emphasis>with</emphasis> time zone to
10749 time stamp <emphasis>without</emphasis> time zone, as the time would
10750 appear with the session's <varname>TimeZone</varname> value as time zone.
10751 </para>
10752 <para>
10753 <literal>timestamp with time zone '2001-02-16 20:38:40-05' at local</literal>
10754 <returnvalue>2001-02-16 18:38:40</returnvalue>
10755 </para></entry>
10756 </row>
10758 <row>
10759 <entry role="func_table_entry"><para role="func_signature">
10760 <type>time with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10761 <returnvalue>time with time zone</returnvalue>
10762 </para>
10763 <para>
10764 Converts given time <emphasis>with</emphasis> time zone to a new time
10765 zone. Since no date is supplied, this uses the currently active UTC
10766 offset for the named destination zone.
10767 </para>
10768 <para>
10769 <literal>time with time zone '05:34:17-05' at time zone 'UTC'</literal>
10770 <returnvalue>10:34:17+00</returnvalue>
10771 </para></entry>
10772 </row>
10774 <row>
10775 <entry role="func_table_entry"><para role="func_signature">
10776 <type>time with time zone</type> <literal>AT LOCAL</literal>
10777 <returnvalue>time with time zone</returnvalue>
10778 </para>
10779 <para>
10780 Converts given time <emphasis>with</emphasis> time zone to a new time
10781 zone. Since no date is supplied, this uses the currently active UTC
10782 offset for the session's <varname>TimeZone</varname> value.
10783 </para>
10784 <para>
10785 Assuming the session's <varname>TimeZone</varname> is set to <literal>UTC</literal>:
10786 </para>
10787 <para>
10788 <literal>time with time zone '05:34:17-05' at local</literal>
10789 <returnvalue>10:34:17+00</returnvalue>
10790 </para></entry>
10791 </row>
10792 </tbody>
10793 </tgroup>
10794 </table>
10796 <para>
10797 In these expressions, the desired time zone <replaceable>zone</replaceable> can be
10798 specified either as a text value (e.g., <literal>'America/Los_Angeles'</literal>)
10799 or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
10800 In the text case, a time zone name can be specified in any of the ways
10801 described in <xref linkend="datatype-timezones"/>.
10802 The interval case is only useful for zones that have fixed offsets from
10803 UTC, so it is not very common in practice.
10804 </para>
10806 <para>
10807 The syntax <literal>AT LOCAL</literal> may be used as shorthand for
10808 <literal>AT TIME ZONE <replaceable>local</replaceable></literal>, where
10809 <replaceable>local</replaceable> is the session's
10810 <varname>TimeZone</varname> value.
10811 </para>
10813 <para>
10814 Examples (assuming the current <xref linkend="guc-timezone"/> setting
10815 is <literal>America/Los_Angeles</literal>):
10816 <screen>
10817 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
10818 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
10820 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/Denver';
10821 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
10823 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
10824 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 05:38:40</computeroutput>
10826 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT LOCAL;
10827 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 17:38:40</computeroutput>
10829 SELECT TIME WITH TIME ZONE '20:38:40-05' AT LOCAL;
10830 <lineannotation>Result: </lineannotation><computeroutput>17:38:40</computeroutput>
10831 </screen>
10832 The first example adds a time zone to a value that lacks it, and
10833 displays the value using the current <varname>TimeZone</varname>
10834 setting. The second example shifts the time stamp with time zone value
10835 to the specified time zone, and returns the value without a time zone.
10836 This allows storage and display of values different from the current
10837 <varname>TimeZone</varname> setting. The third example converts
10838 Tokyo time to Chicago time. The fourth example shifts the time stamp
10839 with time zone value to the time zone currently specified by the
10840 <varname>TimeZone</varname> setting and returns the value without a
10841 time zone.
10842 </para>
10844 <para>
10845 The fifth example is a cautionary tale. Due to the fact that there is no
10846 date associated with the input value, the conversion is made using the
10847 current date of the session. Therefore, this static example may show a wrong
10848 result depending on the time of the year it is viewed because
10849 <literal>'America/Los_Angeles'</literal> observes Daylight Savings Time.
10850 </para>
10852 <para>
10853 The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
10854 <replaceable>timestamp</replaceable>)</literal> is equivalent to the SQL-conforming construct
10855 <literal><replaceable>timestamp</replaceable> AT TIME ZONE
10856 <replaceable>zone</replaceable></literal>.
10857 </para>
10859 <para>
10860 The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
10861 <replaceable>time</replaceable>)</literal> is equivalent to the SQL-conforming construct
10862 <literal><replaceable>time</replaceable> AT TIME ZONE
10863 <replaceable>zone</replaceable></literal>.
10864 </para>
10866 <para>
10867 The function <literal><function>timezone</function>(<replaceable>timestamp</replaceable>)</literal>
10868 is equivalent to the SQL-conforming construct <literal><replaceable>timestamp</replaceable>
10869 AT LOCAL</literal>.
10870 </para>
10872 <para>
10873 The function <literal><function>timezone</function>(<replaceable>time</replaceable>)</literal>
10874 is equivalent to the SQL-conforming construct <literal><replaceable>time</replaceable>
10875 AT LOCAL</literal>.
10876 </para>
10877 </sect2>
10879 <sect2 id="functions-datetime-current">
10880 <title>Current Date/Time</title>
10882 <indexterm>
10883 <primary>date</primary>
10884 <secondary>current</secondary>
10885 </indexterm>
10887 <indexterm>
10888 <primary>time</primary>
10889 <secondary>current</secondary>
10890 </indexterm>
10892 <para>
10893 <productname>PostgreSQL</productname> provides a number of functions
10894 that return values related to the current date and time. These
10895 SQL-standard functions all return values based on the start time of
10896 the current transaction:
10897 <synopsis>
10898 CURRENT_DATE
10899 CURRENT_TIME
10900 CURRENT_TIMESTAMP
10901 CURRENT_TIME(<replaceable>precision</replaceable>)
10902 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
10903 LOCALTIME
10904 LOCALTIMESTAMP
10905 LOCALTIME(<replaceable>precision</replaceable>)
10906 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
10907 </synopsis>
10908 </para>
10910 <para>
10911 <function>CURRENT_TIME</function> and
10912 <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
10913 <function>LOCALTIME</function> and
10914 <function>LOCALTIMESTAMP</function> deliver values without time zone.
10915 </para>
10917 <para>
10918 <function>CURRENT_TIME</function>,
10919 <function>CURRENT_TIMESTAMP</function>,
10920 <function>LOCALTIME</function>, and
10921 <function>LOCALTIMESTAMP</function>
10922 can optionally take
10923 a precision parameter, which causes the result to be rounded
10924 to that many fractional digits in the seconds field. Without a precision parameter,
10925 the result is given to the full available precision.
10926 </para>
10928 <para>
10929 Some examples:
10930 <screen>
10931 SELECT CURRENT_TIME;
10932 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
10934 SELECT CURRENT_DATE;
10935 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23</computeroutput>
10937 SELECT CURRENT_TIMESTAMP;
10938 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522-05</computeroutput>
10940 SELECT CURRENT_TIMESTAMP(2);
10941 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.66-05</computeroutput>
10943 SELECT LOCALTIMESTAMP;
10944 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522</computeroutput>
10945 </screen>
10946 </para>
10948 <para>
10949 Since these functions return
10950 the start time of the current transaction, their values do not
10951 change during the transaction. This is considered a feature:
10952 the intent is to allow a single transaction to have a consistent
10953 notion of the <quote>current</quote> time, so that multiple
10954 modifications within the same transaction bear the same
10955 time stamp.
10956 </para>
10958 <note>
10959 <para>
10960 Other database systems might advance these values more
10961 frequently.
10962 </para>
10963 </note>
10965 <para>
10966 <productname>PostgreSQL</productname> also provides functions that
10967 return the start time of the current statement, as well as the actual
10968 current time at the instant the function is called. The complete list
10969 of non-SQL-standard time functions is:
10970 <synopsis>
10971 transaction_timestamp()
10972 statement_timestamp()
10973 clock_timestamp()
10974 timeofday()
10975 now()
10976 </synopsis>
10977 </para>
10979 <para>
10980 <function>transaction_timestamp()</function> is equivalent to
10981 <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
10982 what it returns.
10983 <function>statement_timestamp()</function> returns the start time of the current
10984 statement (more specifically, the time of receipt of the latest command
10985 message from the client).
10986 <function>statement_timestamp()</function> and <function>transaction_timestamp()</function>
10987 return the same value during the first command of a transaction, but might
10988 differ during subsequent commands.
10989 <function>clock_timestamp()</function> returns the actual current time, and
10990 therefore its value changes even within a single SQL command.
10991 <function>timeofday()</function> is a historical
10992 <productname>PostgreSQL</productname> function. Like
10993 <function>clock_timestamp()</function>, it returns the actual current time,
10994 but as a formatted <type>text</type> string rather than a <type>timestamp
10995 with time zone</type> value.
10996 <function>now()</function> is a traditional <productname>PostgreSQL</productname>
10997 equivalent to <function>transaction_timestamp()</function>.
10998 </para>
11000 <para>
11001 All the date/time data types also accept the special literal value
11002 <literal>now</literal> to specify the current date and time (again,
11003 interpreted as the transaction start time). Thus,
11004 the following three all return the same result:
11005 <programlisting>
11006 SELECT CURRENT_TIMESTAMP;
11007 SELECT now();
11008 SELECT TIMESTAMP 'now'; -- but see tip below
11009 </programlisting>
11010 </para>
11012 <tip>
11013 <para>
11014 Do not use the third form when specifying a value to be evaluated later,
11015 for example in a <literal>DEFAULT</literal> clause for a table column.
11016 The system will convert <literal>now</literal>
11017 to a <type>timestamp</type> as soon as the constant is parsed, so that when
11018 the default value is needed,
11019 the time of the table creation would be used! The first two
11020 forms will not be evaluated until the default value is used,
11021 because they are function calls. Thus they will give the desired
11022 behavior of defaulting to the time of row insertion.
11023 (See also <xref linkend="datatype-datetime-special-values"/>.)
11024 </para>
11025 </tip>
11026 </sect2>
11028 <sect2 id="functions-datetime-delay">
11029 <title>Delaying Execution</title>
11031 <indexterm>
11032 <primary>pg_sleep</primary>
11033 </indexterm>
11034 <indexterm>
11035 <primary>pg_sleep_for</primary>
11036 </indexterm>
11037 <indexterm>
11038 <primary>pg_sleep_until</primary>
11039 </indexterm>
11040 <indexterm>
11041 <primary>sleep</primary>
11042 </indexterm>
11043 <indexterm>
11044 <primary>delay</primary>
11045 </indexterm>
11047 <para>
11048 The following functions are available to delay execution of the server
11049 process:
11050 <synopsis>
11051 pg_sleep ( <type>double precision</type> )
11052 pg_sleep_for ( <type>interval</type> )
11053 pg_sleep_until ( <type>timestamp with time zone</type> )
11054 </synopsis>
11056 <function>pg_sleep</function> makes the current session's process
11057 sleep until the given number of seconds have
11058 elapsed. Fractional-second delays can be specified.
11059 <function>pg_sleep_for</function> is a convenience function to
11060 allow the sleep time to be specified as an <type>interval</type>.
11061 <function>pg_sleep_until</function> is a convenience function for when
11062 a specific wake-up time is desired.
11063 For example:
11065 <programlisting>
11066 SELECT pg_sleep(1.5);
11067 SELECT pg_sleep_for('5 minutes');
11068 SELECT pg_sleep_until('tomorrow 03:00');
11069 </programlisting>
11070 </para>
11072 <note>
11073 <para>
11074 The effective resolution of the sleep interval is platform-specific;
11075 0.01 seconds is a common value. The sleep delay will be at least as long
11076 as specified. It might be longer depending on factors such as server load.
11077 In particular, <function>pg_sleep_until</function> is not guaranteed to
11078 wake up exactly at the specified time, but it will not wake up any earlier.
11079 </para>
11080 </note>
11082 <warning>
11083 <para>
11084 Make sure that your session does not hold more locks than necessary
11085 when calling <function>pg_sleep</function> or its variants. Otherwise
11086 other sessions might have to wait for your sleeping process, slowing down
11087 the entire system.
11088 </para>
11089 </warning>
11090 </sect2>
11092 </sect1>
11095 <sect1 id="functions-enum">
11096 <title>Enum Support Functions</title>
11098 <para>
11099 For enum types (described in <xref linkend="datatype-enum"/>),
11100 there are several functions that allow cleaner programming without
11101 hard-coding particular values of an enum type.
11102 These are listed in <xref linkend="functions-enum-table"/>. The examples
11103 assume an enum type created as:
11105 <programlisting>
11106 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
11107 </programlisting>
11109 </para>
11111 <table id="functions-enum-table">
11112 <title>Enum Support Functions</title>
11113 <tgroup cols="1">
11114 <thead>
11115 <row>
11116 <entry role="func_table_entry"><para role="func_signature">
11117 Function
11118 </para>
11119 <para>
11120 Description
11121 </para>
11122 <para>
11123 Example(s)
11124 </para></entry>
11125 </row>
11126 </thead>
11128 <tbody>
11129 <row>
11130 <entry role="func_table_entry"><para role="func_signature">
11131 <indexterm>
11132 <primary>enum_first</primary>
11133 </indexterm>
11134 <function>enum_first</function> ( <type>anyenum</type> )
11135 <returnvalue>anyenum</returnvalue>
11136 </para>
11137 <para>
11138 Returns the first value of the input enum type.
11139 </para>
11140 <para>
11141 <literal>enum_first(null::rainbow)</literal>
11142 <returnvalue>red</returnvalue>
11143 </para></entry>
11144 </row>
11145 <row>
11146 <entry role="func_table_entry"><para role="func_signature">
11147 <indexterm>
11148 <primary>enum_last</primary>
11149 </indexterm>
11150 <function>enum_last</function> ( <type>anyenum</type> )
11151 <returnvalue>anyenum</returnvalue>
11152 </para>
11153 <para>
11154 Returns the last value of the input enum type.
11155 </para>
11156 <para>
11157 <literal>enum_last(null::rainbow)</literal>
11158 <returnvalue>purple</returnvalue>
11159 </para></entry>
11160 </row>
11161 <row>
11162 <entry role="func_table_entry"><para role="func_signature">
11163 <indexterm>
11164 <primary>enum_range</primary>
11165 </indexterm>
11166 <function>enum_range</function> ( <type>anyenum</type> )
11167 <returnvalue>anyarray</returnvalue>
11168 </para>
11169 <para>
11170 Returns all values of the input enum type in an ordered array.
11171 </para>
11172 <para>
11173 <literal>enum_range(null::rainbow)</literal>
11174 <returnvalue>{red,orange,yellow,&zwsp;green,blue,purple}</returnvalue>
11175 </para></entry>
11176 </row>
11177 <row>
11178 <entry role="func_table_entry"><para role="func_signature">
11179 <function>enum_range</function> ( <type>anyenum</type>, <type>anyenum</type> )
11180 <returnvalue>anyarray</returnvalue>
11181 </para>
11182 <para>
11183 Returns the range between the two given enum values, as an ordered
11184 array. The values must be from the same enum type. If the first
11185 parameter is null, the result will start with the first value of
11186 the enum type.
11187 If the second parameter is null, the result will end with the last
11188 value of the enum type.
11189 </para>
11190 <para>
11191 <literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal>
11192 <returnvalue>{orange,yellow,green}</returnvalue>
11193 </para>
11194 <para>
11195 <literal>enum_range(NULL, 'green'::rainbow)</literal>
11196 <returnvalue>{red,orange,&zwsp;yellow,green}</returnvalue>
11197 </para>
11198 <para>
11199 <literal>enum_range('orange'::rainbow, NULL)</literal>
11200 <returnvalue>{orange,yellow,green,&zwsp;blue,purple}</returnvalue>
11201 </para></entry>
11202 </row>
11203 </tbody>
11204 </tgroup>
11205 </table>
11207 <para>
11208 Notice that except for the two-argument form of <function>enum_range</function>,
11209 these functions disregard the specific value passed to them; they care
11210 only about its declared data type. Either null or a specific value of
11211 the type can be passed, with the same result. It is more common to
11212 apply these functions to a table column or function argument than to
11213 a hardwired type name as used in the examples.
11214 </para>
11215 </sect1>
11217 <sect1 id="functions-geometry">
11218 <title>Geometric Functions and Operators</title>
11220 <para>
11221 The geometric types <type>point</type>, <type>box</type>,
11222 <type>lseg</type>, <type>line</type>, <type>path</type>,
11223 <type>polygon</type>, and <type>circle</type> have a large set of
11224 native support functions and operators, shown in <xref
11225 linkend="functions-geometry-op-table"/>, <xref
11226 linkend="functions-geometry-func-table"/>, and <xref
11227 linkend="functions-geometry-conv-table"/>.
11228 </para>
11230 <table id="functions-geometry-op-table">
11231 <title>Geometric Operators</title>
11232 <tgroup cols="1">
11233 <thead>
11234 <row>
11235 <entry role="func_table_entry"><para role="func_signature">
11236 Operator
11237 </para>
11238 <para>
11239 Description
11240 </para>
11241 <para>
11242 Example(s)
11243 </para></entry>
11244 </row>
11245 </thead>
11247 <tbody>
11248 <row>
11249 <entry role="func_table_entry"><para role="func_signature">
11250 <replaceable>geometric_type</replaceable> <literal>+</literal> <type>point</type>
11251 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11252 </para>
11253 <para>
11254 Adds the coordinates of the second <type>point</type> to those of each
11255 point of the first argument, thus performing translation.
11256 Available for <type>point</type>, <type>box</type>, <type>path</type>,
11257 <type>circle</type>.
11258 </para>
11259 <para>
11260 <literal>box '(1,1),(0,0)' + point '(2,0)'</literal>
11261 <returnvalue>(3,1),(2,0)</returnvalue>
11262 </para></entry>
11263 </row>
11265 <row>
11266 <entry role="func_table_entry"><para role="func_signature">
11267 <type>path</type> <literal>+</literal> <type>path</type>
11268 <returnvalue>path</returnvalue>
11269 </para>
11270 <para>
11271 Concatenates two open paths (returns NULL if either path is closed).
11272 </para>
11273 <para>
11274 <literal>path '[(0,0),(1,1)]' + path '[(2,2),(3,3),(4,4)]'</literal>
11275 <returnvalue>[(0,0),(1,1),(2,2),(3,3),(4,4)]</returnvalue>
11276 </para></entry>
11277 </row>
11279 <row>
11280 <entry role="func_table_entry"><para role="func_signature">
11281 <replaceable>geometric_type</replaceable> <literal>-</literal> <type>point</type>
11282 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11283 </para>
11284 <para>
11285 Subtracts the coordinates of the second <type>point</type> from those
11286 of each point of the first argument, thus performing translation.
11287 Available for <type>point</type>, <type>box</type>, <type>path</type>,
11288 <type>circle</type>.
11289 </para>
11290 <para>
11291 <literal>box '(1,1),(0,0)' - point '(2,0)'</literal>
11292 <returnvalue>(-1,1),(-2,0)</returnvalue>
11293 </para></entry>
11294 </row>
11296 <row>
11297 <entry role="func_table_entry"><para role="func_signature">
11298 <replaceable>geometric_type</replaceable> <literal>*</literal> <type>point</type>
11299 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11300 </para>
11301 <para>
11302 Multiplies each point of the first argument by the second
11303 <type>point</type> (treating a point as being a complex number
11304 represented by real and imaginary parts, and performing standard
11305 complex multiplication). If one interprets
11306 the second <type>point</type> as a vector, this is equivalent to
11307 scaling the object's size and distance from the origin by the length
11308 of the vector, and rotating it counterclockwise around the origin by
11309 the vector's angle from the <replaceable>x</replaceable> axis.
11310 Available for <type>point</type>, <type>box</type>,<footnote
11311 id="functions-geometry-rotation-fn"><para><quote>Rotating</quote> a
11312 box with these operators only moves its corner points: the box is
11313 still considered to have sides parallel to the axes. Hence the box's
11314 size is not preserved, as a true rotation would do.</para></footnote>
11315 <type>path</type>, <type>circle</type>.
11316 </para>
11317 <para>
11318 <literal>path '((0,0),(1,0),(1,1))' * point '(3.0,0)'</literal>
11319 <returnvalue>((0,0),(3,0),(3,3))</returnvalue>
11320 </para>
11321 <para>
11322 <literal>path '((0,0),(1,0),(1,1))' * point(cosd(45), sind(45))</literal>
11323 <returnvalue>((0,0),&zwsp;(0.7071067811865475,0.7071067811865475),&zwsp;(0,1.414213562373095))</returnvalue>
11324 </para></entry>
11325 </row>
11327 <row>
11328 <entry role="func_table_entry"><para role="func_signature">
11329 <replaceable>geometric_type</replaceable> <literal>/</literal> <type>point</type>
11330 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11331 </para>
11332 <para>
11333 Divides each point of the first argument by the second
11334 <type>point</type> (treating a point as being a complex number
11335 represented by real and imaginary parts, and performing standard
11336 complex division). If one interprets
11337 the second <type>point</type> as a vector, this is equivalent to
11338 scaling the object's size and distance from the origin down by the
11339 length of the vector, and rotating it clockwise around the origin by
11340 the vector's angle from the <replaceable>x</replaceable> axis.
11341 Available for <type>point</type>, <type>box</type>,<footnoteref
11342 linkend="functions-geometry-rotation-fn"/> <type>path</type>,
11343 <type>circle</type>.
11344 </para>
11345 <para>
11346 <literal>path '((0,0),(1,0),(1,1))' / point '(2.0,0)'</literal>
11347 <returnvalue>((0,0),(0.5,0),(0.5,0.5))</returnvalue>
11348 </para>
11349 <para>
11350 <literal>path '((0,0),(1,0),(1,1))' / point(cosd(45), sind(45))</literal>
11351 <returnvalue>((0,0),&zwsp;(0.7071067811865476,-0.7071067811865476),&zwsp;(1.4142135623730951,0))</returnvalue>
11352 </para></entry>
11353 </row>
11355 <row>
11356 <entry role="func_table_entry"><para role="func_signature">
11357 <literal>@-@</literal> <replaceable>geometric_type</replaceable>
11358 <returnvalue>double precision</returnvalue>
11359 </para>
11360 <para>
11361 Computes the total length.
11362 Available for <type>lseg</type>, <type>path</type>.
11363 </para>
11364 <para>
11365 <literal>@-@ path '[(0,0),(1,0),(1,1)]'</literal>
11366 <returnvalue>2</returnvalue>
11367 </para></entry>
11368 </row>
11370 <row>
11371 <entry role="func_table_entry"><para role="func_signature">
11372 <literal>@@</literal> <replaceable>geometric_type</replaceable>
11373 <returnvalue>point</returnvalue>
11374 </para>
11375 <para>
11376 Computes the center point.
11377 Available for <type>box</type>, <type>lseg</type>,
11378 <type>polygon</type>, <type>circle</type>.
11379 </para>
11380 <para>
11381 <literal>@@ box '(2,2),(0,0)'</literal>
11382 <returnvalue>(1,1)</returnvalue>
11383 </para></entry>
11384 </row>
11386 <row>
11387 <entry role="func_table_entry"><para role="func_signature">
11388 <literal>#</literal> <replaceable>geometric_type</replaceable>
11389 <returnvalue>integer</returnvalue>
11390 </para>
11391 <para>
11392 Returns the number of points.
11393 Available for <type>path</type>, <type>polygon</type>.
11394 </para>
11395 <para>
11396 <literal># path '((1,0),(0,1),(-1,0))'</literal>
11397 <returnvalue>3</returnvalue>
11398 </para></entry>
11399 </row>
11401 <row>
11402 <entry role="func_table_entry"><para role="func_signature">
11403 <replaceable>geometric_type</replaceable> <literal>#</literal> <replaceable>geometric_type</replaceable>
11404 <returnvalue>point</returnvalue>
11405 </para>
11406 <para>
11407 Computes the point of intersection, or NULL if there is none.
11408 Available for <type>lseg</type>, <type>line</type>.
11409 </para>
11410 <para>
11411 <literal>lseg '[(0,0),(1,1)]' # lseg '[(1,0),(0,1)]'</literal>
11412 <returnvalue>(0.5,0.5)</returnvalue>
11413 </para></entry>
11414 </row>
11416 <row>
11417 <entry role="func_table_entry"><para role="func_signature">
11418 <type>box</type> <literal>#</literal> <type>box</type>
11419 <returnvalue>box</returnvalue>
11420 </para>
11421 <para>
11422 Computes the intersection of two boxes, or NULL if there is none.
11423 </para>
11424 <para>
11425 <literal>box '(2,2),(-1,-1)' # box '(1,1),(-2,-2)'</literal>
11426 <returnvalue>(1,1),(-1,-1)</returnvalue>
11427 </para></entry>
11428 </row>
11430 <row>
11431 <entry role="func_table_entry"><para role="func_signature">
11432 <replaceable>geometric_type</replaceable> <literal>##</literal> <replaceable>geometric_type</replaceable>
11433 <returnvalue>point</returnvalue>
11434 </para>
11435 <para>
11436 Computes the closest point to the first object on the second object.
11437 Available for these pairs of types:
11438 (<type>point</type>, <type>box</type>),
11439 (<type>point</type>, <type>lseg</type>),
11440 (<type>point</type>, <type>line</type>),
11441 (<type>lseg</type>, <type>box</type>),
11442 (<type>lseg</type>, <type>lseg</type>),
11443 (<type>line</type>, <type>lseg</type>).
11444 </para>
11445 <para>
11446 <literal>point '(0,0)' ## lseg '[(2,0),(0,2)]'</literal>
11447 <returnvalue>(1,1)</returnvalue>
11448 </para></entry>
11449 </row>
11451 <row>
11452 <entry role="func_table_entry"><para role="func_signature">
11453 <replaceable>geometric_type</replaceable> <literal>&lt;-&gt;</literal> <replaceable>geometric_type</replaceable>
11454 <returnvalue>double precision</returnvalue>
11455 </para>
11456 <para>
11457 Computes the distance between the objects.
11458 Available for all seven geometric types, for all combinations
11459 of <type>point</type> with another geometric type, and for
11460 these additional pairs of types:
11461 (<type>box</type>, <type>lseg</type>),
11462 (<type>lseg</type>, <type>line</type>),
11463 (<type>polygon</type>, <type>circle</type>)
11464 (and the commutator cases).
11465 </para>
11466 <para>
11467 <literal>circle '&lt;(0,0),1&gt;' &lt;-&gt; circle '&lt;(5,0),1&gt;'</literal>
11468 <returnvalue>3</returnvalue>
11469 </para></entry>
11470 </row>
11472 <row>
11473 <entry role="func_table_entry"><para role="func_signature">
11474 <replaceable>geometric_type</replaceable> <literal>@&gt;</literal> <replaceable>geometric_type</replaceable>
11475 <returnvalue>boolean</returnvalue>
11476 </para>
11477 <para>
11478 Does first object contain second?
11479 Available for these pairs of types:
11480 (<literal>box</literal>, <literal>point</literal>),
11481 (<literal>box</literal>, <literal>box</literal>),
11482 (<literal>path</literal>, <literal>point</literal>),
11483 (<literal>polygon</literal>, <literal>point</literal>),
11484 (<literal>polygon</literal>, <literal>polygon</literal>),
11485 (<literal>circle</literal>, <literal>point</literal>),
11486 (<literal>circle</literal>, <literal>circle</literal>).
11487 </para>
11488 <para>
11489 <literal>circle '&lt;(0,0),2&gt;' @&gt; point '(1,1)'</literal>
11490 <returnvalue>t</returnvalue>
11491 </para></entry>
11492 </row>
11494 <row>
11495 <entry role="func_table_entry"><para role="func_signature">
11496 <replaceable>geometric_type</replaceable> <literal>&lt;@</literal> <replaceable>geometric_type</replaceable>
11497 <returnvalue>boolean</returnvalue>
11498 </para>
11499 <para>
11500 Is first object contained in or on second?
11501 Available for these pairs of types:
11502 (<literal>point</literal>, <literal>box</literal>),
11503 (<literal>point</literal>, <literal>lseg</literal>),
11504 (<literal>point</literal>, <literal>line</literal>),
11505 (<literal>point</literal>, <literal>path</literal>),
11506 (<literal>point</literal>, <literal>polygon</literal>),
11507 (<literal>point</literal>, <literal>circle</literal>),
11508 (<literal>box</literal>, <literal>box</literal>),
11509 (<literal>lseg</literal>, <literal>box</literal>),
11510 (<literal>lseg</literal>, <literal>line</literal>),
11511 (<literal>polygon</literal>, <literal>polygon</literal>),
11512 (<literal>circle</literal>, <literal>circle</literal>).
11513 </para>
11514 <para>
11515 <literal>point '(1,1)' &lt;@ circle '&lt;(0,0),2&gt;'</literal>
11516 <returnvalue>t</returnvalue>
11517 </para></entry>
11518 </row>
11520 <row>
11521 <entry role="func_table_entry"><para role="func_signature">
11522 <replaceable>geometric_type</replaceable> <literal>&amp;&amp;</literal> <replaceable>geometric_type</replaceable>
11523 <returnvalue>boolean</returnvalue>
11524 </para>
11525 <para>
11526 Do these objects overlap? (One point in common makes this true.)
11527 Available for <type>box</type>, <type>polygon</type>,
11528 <type>circle</type>.
11529 </para>
11530 <para>
11531 <literal>box '(1,1),(0,0)' &amp;&amp; box '(2,2),(0,0)'</literal>
11532 <returnvalue>t</returnvalue>
11533 </para></entry>
11534 </row>
11536 <row>
11537 <entry role="func_table_entry"><para role="func_signature">
11538 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;</literal> <replaceable>geometric_type</replaceable>
11539 <returnvalue>boolean</returnvalue>
11540 </para>
11541 <para>
11542 Is first object strictly left of second?
11543 Available for <type>point</type>, <type>box</type>,
11544 <type>polygon</type>, <type>circle</type>.
11545 </para>
11546 <para>
11547 <literal>circle '&lt;(0,0),1&gt;' &lt;&lt; circle '&lt;(5,0),1&gt;'</literal>
11548 <returnvalue>t</returnvalue>
11549 </para></entry>
11550 </row>
11552 <row>
11553 <entry role="func_table_entry"><para role="func_signature">
11554 <replaceable>geometric_type</replaceable> <literal>&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11555 <returnvalue>boolean</returnvalue>
11556 </para>
11557 <para>
11558 Is first object strictly right of second?
11559 Available for <type>point</type>, <type>box</type>,
11560 <type>polygon</type>, <type>circle</type>.
11561 </para>
11562 <para>
11563 <literal>circle '&lt;(5,0),1&gt;' &gt;&gt; circle '&lt;(0,0),1&gt;'</literal>
11564 <returnvalue>t</returnvalue>
11565 </para></entry>
11566 </row>
11568 <row>
11569 <entry role="func_table_entry"><para role="func_signature">
11570 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;</literal> <replaceable>geometric_type</replaceable>
11571 <returnvalue>boolean</returnvalue>
11572 </para>
11573 <para>
11574 Does first object not extend to the right of second?
11575 Available for <type>box</type>, <type>polygon</type>,
11576 <type>circle</type>.
11577 </para>
11578 <para>
11579 <literal>box '(1,1),(0,0)' &amp;&lt; box '(2,2),(0,0)'</literal>
11580 <returnvalue>t</returnvalue>
11581 </para></entry>
11582 </row>
11584 <row>
11585 <entry role="func_table_entry"><para role="func_signature">
11586 <replaceable>geometric_type</replaceable> <literal>&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11587 <returnvalue>boolean</returnvalue>
11588 </para>
11589 <para>
11590 Does first object not extend to the left of second?
11591 Available for <type>box</type>, <type>polygon</type>,
11592 <type>circle</type>.
11593 </para>
11594 <para>
11595 <literal>box '(3,3),(0,0)' &amp;&gt; box '(2,2),(0,0)'</literal>
11596 <returnvalue>t</returnvalue>
11597 </para></entry>
11598 </row>
11600 <row>
11601 <entry role="func_table_entry"><para role="func_signature">
11602 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;|</literal> <replaceable>geometric_type</replaceable>
11603 <returnvalue>boolean</returnvalue>
11604 </para>
11605 <para>
11606 Is first object strictly below second?
11607 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11608 <type>circle</type>.
11609 </para>
11610 <para>
11611 <literal>box '(3,3),(0,0)' &lt;&lt;| box '(5,5),(3,4)'</literal>
11612 <returnvalue>t</returnvalue>
11613 </para></entry>
11614 </row>
11616 <row>
11617 <entry role="func_table_entry"><para role="func_signature">
11618 <replaceable>geometric_type</replaceable> <literal>|&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11619 <returnvalue>boolean</returnvalue>
11620 </para>
11621 <para>
11622 Is first object strictly above second?
11623 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11624 <type>circle</type>.
11625 </para>
11626 <para>
11627 <literal>box '(5,5),(3,4)' |&gt;&gt; box '(3,3),(0,0)'</literal>
11628 <returnvalue>t</returnvalue>
11629 </para></entry>
11630 </row>
11632 <row>
11633 <entry role="func_table_entry"><para role="func_signature">
11634 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;|</literal> <replaceable>geometric_type</replaceable>
11635 <returnvalue>boolean</returnvalue>
11636 </para>
11637 <para>
11638 Does first object not extend above second?
11639 Available for <type>box</type>, <type>polygon</type>,
11640 <type>circle</type>.
11641 </para>
11642 <para>
11643 <literal>box '(1,1),(0,0)' &amp;&lt;| box '(2,2),(0,0)'</literal>
11644 <returnvalue>t</returnvalue>
11645 </para></entry>
11646 </row>
11648 <row>
11649 <entry role="func_table_entry"><para role="func_signature">
11650 <replaceable>geometric_type</replaceable> <literal>|&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11651 <returnvalue>boolean</returnvalue>
11652 </para>
11653 <para>
11654 Does first object not extend below second?
11655 Available for <type>box</type>, <type>polygon</type>,
11656 <type>circle</type>.
11657 </para>
11658 <para>
11659 <literal>box '(3,3),(0,0)' |&amp;&gt; box '(2,2),(0,0)'</literal>
11660 <returnvalue>t</returnvalue>
11661 </para></entry>
11662 </row>
11664 <row>
11665 <entry role="func_table_entry"><para role="func_signature">
11666 <type>box</type> <literal>&lt;^</literal> <type>box</type>
11667 <returnvalue>boolean</returnvalue>
11668 </para>
11669 <para>
11670 Is first object below second (allows edges to touch)?
11671 </para>
11672 <para>
11673 <literal>box '((1,1),(0,0))' &lt;^ box '((2,2),(1,1))'</literal>
11674 <returnvalue>t</returnvalue>
11675 </para></entry>
11676 </row>
11678 <row>
11679 <entry role="func_table_entry"><para role="func_signature">
11680 <type>box</type> <literal>&gt;^</literal> <type>box</type>
11681 <returnvalue>boolean</returnvalue>
11682 </para>
11683 <para>
11684 Is first object above second (allows edges to touch)?
11685 </para>
11686 <para>
11687 <literal>box '((2,2),(1,1))' &gt;^ box '((1,1),(0,0))'</literal>
11688 <returnvalue>t</returnvalue>
11689 </para></entry>
11690 </row>
11692 <row>
11693 <entry role="func_table_entry"><para role="func_signature">
11694 <replaceable>geometric_type</replaceable> <literal>?#</literal> <replaceable>geometric_type</replaceable>
11695 <returnvalue>boolean</returnvalue>
11696 </para>
11697 <para>
11698 Do these objects intersect?
11699 Available for these pairs of types:
11700 (<type>box</type>, <type>box</type>),
11701 (<type>lseg</type>, <type>box</type>),
11702 (<type>lseg</type>, <type>lseg</type>),
11703 (<type>lseg</type>, <type>line</type>),
11704 (<type>line</type>, <type>box</type>),
11705 (<type>line</type>, <type>line</type>),
11706 (<type>path</type>, <type>path</type>).
11707 </para>
11708 <para>
11709 <literal>lseg '[(-1,0),(1,0)]' ?# box '(2,2),(-2,-2)'</literal>
11710 <returnvalue>t</returnvalue>
11711 </para></entry>
11712 </row>
11714 <row>
11715 <entry role="func_table_entry"><para role="func_signature">
11716 <literal>?-</literal> <type>line</type>
11717 <returnvalue>boolean</returnvalue>
11718 </para>
11719 <para role="func_signature">
11720 <literal>?-</literal> <type>lseg</type>
11721 <returnvalue>boolean</returnvalue>
11722 </para>
11723 <para>
11724 Is line horizontal?
11725 </para>
11726 <para>
11727 <literal>?- lseg '[(-1,0),(1,0)]'</literal>
11728 <returnvalue>t</returnvalue>
11729 </para></entry>
11730 </row>
11732 <row>
11733 <entry role="func_table_entry"><para role="func_signature">
11734 <type>point</type> <literal>?-</literal> <type>point</type>
11735 <returnvalue>boolean</returnvalue>
11736 </para>
11737 <para>
11738 Are points horizontally aligned (that is, have same y coordinate)?
11739 </para>
11740 <para>
11741 <literal>point '(1,0)' ?- point '(0,0)'</literal>
11742 <returnvalue>t</returnvalue>
11743 </para></entry>
11744 </row>
11746 <row>
11747 <entry role="func_table_entry"><para role="func_signature">
11748 <literal>?|</literal> <type>line</type>
11749 <returnvalue>boolean</returnvalue>
11750 </para>
11751 <para role="func_signature">
11752 <literal>?|</literal> <type>lseg</type>
11753 <returnvalue>boolean</returnvalue>
11754 </para>
11755 <para>
11756 Is line vertical?
11757 </para>
11758 <para>
11759 <literal>?| lseg '[(-1,0),(1,0)]'</literal>
11760 <returnvalue>f</returnvalue>
11761 </para></entry>
11762 </row>
11764 <row>
11765 <entry role="func_table_entry"><para role="func_signature">
11766 <type>point</type> <literal>?|</literal> <type>point</type>
11767 <returnvalue>boolean</returnvalue>
11768 </para>
11769 <para>
11770 Are points vertically aligned (that is, have same x coordinate)?
11771 </para>
11772 <para>
11773 <literal>point '(0,1)' ?| point '(0,0)'</literal>
11774 <returnvalue>t</returnvalue>
11775 </para></entry>
11776 </row>
11778 <row>
11779 <entry role="func_table_entry"><para role="func_signature">
11780 <type>line</type> <literal>?-|</literal> <type>line</type>
11781 <returnvalue>boolean</returnvalue>
11782 </para>
11783 <para role="func_signature">
11784 <type>lseg</type> <literal>?-|</literal> <type>lseg</type>
11785 <returnvalue>boolean</returnvalue>
11786 </para>
11787 <para>
11788 Are lines perpendicular?
11789 </para>
11790 <para>
11791 <literal>lseg '[(0,0),(0,1)]' ?-| lseg '[(0,0),(1,0)]'</literal>
11792 <returnvalue>t</returnvalue>
11793 </para></entry>
11794 </row>
11796 <row>
11797 <entry role="func_table_entry"><para role="func_signature">
11798 <type>line</type> <literal>?||</literal> <type>line</type>
11799 <returnvalue>boolean</returnvalue>
11800 </para>
11801 <para role="func_signature">
11802 <type>lseg</type> <literal>?||</literal> <type>lseg</type>
11803 <returnvalue>boolean</returnvalue>
11804 </para>
11805 <para>
11806 Are lines parallel?
11807 </para>
11808 <para>
11809 <literal>lseg '[(-1,0),(1,0)]' ?|| lseg '[(-1,2),(1,2)]'</literal>
11810 <returnvalue>t</returnvalue>
11811 </para></entry>
11812 </row>
11814 <row>
11815 <entry role="func_table_entry"><para role="func_signature">
11816 <replaceable>geometric_type</replaceable> <literal>~=</literal> <replaceable>geometric_type</replaceable>
11817 <returnvalue>boolean</returnvalue>
11818 </para>
11819 <para>
11820 Are these objects the same?
11821 Available for <type>point</type>, <type>box</type>,
11822 <type>polygon</type>, <type>circle</type>.
11823 </para>
11824 <para>
11825 <literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal>
11826 <returnvalue>t</returnvalue>
11827 </para></entry>
11828 </row>
11829 </tbody>
11830 </tgroup>
11831 </table>
11833 <caution>
11834 <para>
11835 Note that the <quote>same as</quote> operator, <literal>~=</literal>,
11836 represents the usual notion of equality for the <type>point</type>,
11837 <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
11838 Some of the geometric types also have an <literal>=</literal> operator, but
11839 <literal>=</literal> compares for equal <emphasis>areas</emphasis> only.
11840 The other scalar comparison operators (<literal>&lt;=</literal> and so
11841 on), where available for these types, likewise compare areas.
11842 </para>
11843 </caution>
11845 <note>
11846 <para>
11847 Before <productname>PostgreSQL</productname> 14, the point
11848 is strictly below/above comparison operators <type>point</type>
11849 <literal>&lt;&lt;|</literal> <type>point</type> and <type>point</type>
11850 <literal>|&gt;&gt;</literal> <type>point</type> were respectively
11851 called <literal>&lt;^</literal> and <literal>&gt;^</literal>. These
11852 names are still available, but are deprecated and will eventually be
11853 removed.
11854 </para>
11855 </note>
11857 <table id="functions-geometry-func-table">
11858 <title>Geometric Functions</title>
11859 <tgroup cols="1">
11860 <thead>
11861 <row>
11862 <entry role="func_table_entry"><para role="func_signature">
11863 Function
11864 </para>
11865 <para>
11866 Description
11867 </para>
11868 <para>
11869 Example(s)
11870 </para></entry>
11871 </row>
11872 </thead>
11874 <tbody>
11875 <row>
11876 <entry role="func_table_entry"><para role="func_signature">
11877 <indexterm>
11878 <primary>area</primary>
11879 </indexterm>
11880 <function>area</function> ( <replaceable>geometric_type</replaceable> )
11881 <returnvalue>double precision</returnvalue>
11882 </para>
11883 <para>
11884 Computes area.
11885 Available for <type>box</type>, <type>path</type>, <type>circle</type>.
11886 A <type>path</type> input must be closed, else NULL is returned.
11887 Also, if the <type>path</type> is self-intersecting, the result may be
11888 meaningless.
11889 </para>
11890 <para>
11891 <literal>area(box '(2,2),(0,0)')</literal>
11892 <returnvalue>4</returnvalue>
11893 </para></entry>
11894 </row>
11896 <row>
11897 <entry role="func_table_entry"><para role="func_signature">
11898 <indexterm>
11899 <primary>center</primary>
11900 </indexterm>
11901 <function>center</function> ( <replaceable>geometric_type</replaceable> )
11902 <returnvalue>point</returnvalue>
11903 </para>
11904 <para>
11905 Computes center point.
11906 Available for <type>box</type>, <type>circle</type>.
11907 </para>
11908 <para>
11909 <literal>center(box '(1,2),(0,0)')</literal>
11910 <returnvalue>(0.5,1)</returnvalue>
11911 </para></entry>
11912 </row>
11914 <row>
11915 <entry role="func_table_entry"><para role="func_signature">
11916 <indexterm>
11917 <primary>diagonal</primary>
11918 </indexterm>
11919 <function>diagonal</function> ( <type>box</type> )
11920 <returnvalue>lseg</returnvalue>
11921 </para>
11922 <para>
11923 Extracts box's diagonal as a line segment
11924 (same as <function>lseg(box)</function>).
11925 </para>
11926 <para>
11927 <literal>diagonal(box '(1,2),(0,0)')</literal>
11928 <returnvalue>[(1,2),(0,0)]</returnvalue>
11929 </para></entry>
11930 </row>
11932 <row>
11933 <entry role="func_table_entry"><para role="func_signature">
11934 <indexterm>
11935 <primary>diameter</primary>
11936 </indexterm>
11937 <function>diameter</function> ( <type>circle</type> )
11938 <returnvalue>double precision</returnvalue>
11939 </para>
11940 <para>
11941 Computes diameter of circle.
11942 </para>
11943 <para>
11944 <literal>diameter(circle '&lt;(0,0),2&gt;')</literal>
11945 <returnvalue>4</returnvalue>
11946 </para></entry>
11947 </row>
11949 <row>
11950 <entry role="func_table_entry"><para role="func_signature">
11951 <indexterm>
11952 <primary>height</primary>
11953 </indexterm>
11954 <function>height</function> ( <type>box</type> )
11955 <returnvalue>double precision</returnvalue>
11956 </para>
11957 <para>
11958 Computes vertical size of box.
11959 </para>
11960 <para>
11961 <literal>height(box '(1,2),(0,0)')</literal>
11962 <returnvalue>2</returnvalue>
11963 </para></entry>
11964 </row>
11966 <row>
11967 <entry role="func_table_entry"><para role="func_signature">
11968 <indexterm>
11969 <primary>isclosed</primary>
11970 </indexterm>
11971 <function>isclosed</function> ( <type>path</type> )
11972 <returnvalue>boolean</returnvalue>
11973 </para>
11974 <para>
11975 Is path closed?
11976 </para>
11977 <para>
11978 <literal>isclosed(path '((0,0),(1,1),(2,0))')</literal>
11979 <returnvalue>t</returnvalue>
11980 </para></entry>
11981 </row>
11983 <row>
11984 <entry role="func_table_entry"><para role="func_signature">
11985 <indexterm>
11986 <primary>isopen</primary>
11987 </indexterm>
11988 <function>isopen</function> ( <type>path</type> )
11989 <returnvalue>boolean</returnvalue>
11990 </para>
11991 <para>
11992 Is path open?
11993 </para>
11994 <para>
11995 <literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal>
11996 <returnvalue>t</returnvalue>
11997 </para></entry>
11998 </row>
12000 <row>
12001 <entry role="func_table_entry"><para role="func_signature">
12002 <indexterm>
12003 <primary>length</primary>
12004 </indexterm>
12005 <function>length</function> ( <replaceable>geometric_type</replaceable> )
12006 <returnvalue>double precision</returnvalue>
12007 </para>
12008 <para>
12009 Computes the total length.
12010 Available for <type>lseg</type>, <type>path</type>.
12011 </para>
12012 <para>
12013 <literal>length(path '((-1,0),(1,0))')</literal>
12014 <returnvalue>4</returnvalue>
12015 </para></entry>
12016 </row>
12018 <row>
12019 <entry role="func_table_entry"><para role="func_signature">
12020 <indexterm>
12021 <primary>npoints</primary>
12022 </indexterm>
12023 <function>npoints</function> ( <replaceable>geometric_type</replaceable> )
12024 <returnvalue>integer</returnvalue>
12025 </para>
12026 <para>
12027 Returns the number of points.
12028 Available for <type>path</type>, <type>polygon</type>.
12029 </para>
12030 <para>
12031 <literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal>
12032 <returnvalue>3</returnvalue>
12033 </para></entry>
12034 </row>
12036 <row>
12037 <entry role="func_table_entry"><para role="func_signature">
12038 <indexterm>
12039 <primary>pclose</primary>
12040 </indexterm>
12041 <function>pclose</function> ( <type>path</type> )
12042 <returnvalue>path</returnvalue>
12043 </para>
12044 <para>
12045 Converts path to closed form.
12046 </para>
12047 <para>
12048 <literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal>
12049 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12050 </para></entry>
12051 </row>
12053 <row>
12054 <entry role="func_table_entry"><para role="func_signature">
12055 <indexterm>
12056 <primary>popen</primary>
12057 </indexterm>
12058 <function>popen</function> ( <type>path</type> )
12059 <returnvalue>path</returnvalue>
12060 </para>
12061 <para>
12062 Converts path to open form.
12063 </para>
12064 <para>
12065 <literal>popen(path '((0,0),(1,1),(2,0))')</literal>
12066 <returnvalue>[(0,0),(1,1),(2,0)]</returnvalue>
12067 </para></entry>
12068 </row>
12070 <row>
12071 <entry role="func_table_entry"><para role="func_signature">
12072 <indexterm>
12073 <primary>radius</primary>
12074 </indexterm>
12075 <function>radius</function> ( <type>circle</type> )
12076 <returnvalue>double precision</returnvalue>
12077 </para>
12078 <para>
12079 Computes radius of circle.
12080 </para>
12081 <para>
12082 <literal>radius(circle '&lt;(0,0),2&gt;')</literal>
12083 <returnvalue>2</returnvalue>
12084 </para></entry>
12085 </row>
12087 <row>
12088 <entry role="func_table_entry"><para role="func_signature">
12089 <indexterm>
12090 <primary>slope</primary>
12091 </indexterm>
12092 <function>slope</function> ( <type>point</type>, <type>point</type> )
12093 <returnvalue>double precision</returnvalue>
12094 </para>
12095 <para>
12096 Computes slope of a line drawn through the two points.
12097 </para>
12098 <para>
12099 <literal>slope(point '(0,0)', point '(2,1)')</literal>
12100 <returnvalue>0.5</returnvalue>
12101 </para></entry>
12102 </row>
12104 <row>
12105 <entry role="func_table_entry"><para role="func_signature">
12106 <indexterm>
12107 <primary>width</primary>
12108 </indexterm>
12109 <function>width</function> ( <type>box</type> )
12110 <returnvalue>double precision</returnvalue>
12111 </para>
12112 <para>
12113 Computes horizontal size of box.
12114 </para>
12115 <para>
12116 <literal>width(box '(1,2),(0,0)')</literal>
12117 <returnvalue>1</returnvalue>
12118 </para></entry>
12119 </row>
12120 </tbody>
12121 </tgroup>
12122 </table>
12124 <table id="functions-geometry-conv-table">
12125 <title>Geometric Type Conversion Functions</title>
12126 <tgroup cols="1">
12127 <thead>
12128 <row>
12129 <entry role="func_table_entry"><para role="func_signature">
12130 Function
12131 </para>
12132 <para>
12133 Description
12134 </para>
12135 <para>
12136 Example(s)
12137 </para></entry>
12138 </row>
12139 </thead>
12140 <tbody>
12142 <row>
12143 <entry role="func_table_entry"><para role="func_signature">
12144 <indexterm>
12145 <primary>box</primary>
12146 </indexterm>
12147 <function>box</function> ( <type>circle</type> )
12148 <returnvalue>box</returnvalue>
12149 </para>
12150 <para>
12151 Computes box inscribed within the circle.
12152 </para>
12153 <para>
12154 <literal>box(circle '&lt;(0,0),2&gt;')</literal>
12155 <returnvalue>(1.414213562373095,1.414213562373095),&zwsp;(-1.414213562373095,-1.414213562373095)</returnvalue>
12156 </para></entry>
12157 </row>
12159 <row>
12160 <entry role="func_table_entry"><para role="func_signature">
12161 <function>box</function> ( <type>point</type> )
12162 <returnvalue>box</returnvalue>
12163 </para>
12164 <para>
12165 Converts point to empty box.
12166 </para>
12167 <para>
12168 <literal>box(point '(1,0)')</literal>
12169 <returnvalue>(1,0),(1,0)</returnvalue>
12170 </para></entry>
12171 </row>
12173 <row>
12174 <entry role="func_table_entry"><para role="func_signature">
12175 <function>box</function> ( <type>point</type>, <type>point</type> )
12176 <returnvalue>box</returnvalue>
12177 </para>
12178 <para>
12179 Converts any two corner points to box.
12180 </para>
12181 <para>
12182 <literal>box(point '(0,1)', point '(1,0)')</literal>
12183 <returnvalue>(1,1),(0,0)</returnvalue>
12184 </para></entry>
12185 </row>
12187 <row>
12188 <entry role="func_table_entry"><para role="func_signature">
12189 <function>box</function> ( <type>polygon</type> )
12190 <returnvalue>box</returnvalue>
12191 </para>
12192 <para>
12193 Computes bounding box of polygon.
12194 </para>
12195 <para>
12196 <literal>box(polygon '((0,0),(1,1),(2,0))')</literal>
12197 <returnvalue>(2,1),(0,0)</returnvalue>
12198 </para></entry>
12199 </row>
12201 <row>
12202 <entry role="func_table_entry"><para role="func_signature">
12203 <indexterm>
12204 <primary>bound_box</primary>
12205 </indexterm>
12206 <function>bound_box</function> ( <type>box</type>, <type>box</type> )
12207 <returnvalue>box</returnvalue>
12208 </para>
12209 <para>
12210 Computes bounding box of two boxes.
12211 </para>
12212 <para>
12213 <literal>bound_box(box '(1,1),(0,0)', box '(4,4),(3,3)')</literal>
12214 <returnvalue>(4,4),(0,0)</returnvalue>
12215 </para></entry>
12216 </row>
12218 <row>
12219 <entry role="func_table_entry"><para role="func_signature">
12220 <indexterm>
12221 <primary>circle</primary>
12222 </indexterm>
12223 <function>circle</function> ( <type>box</type> )
12224 <returnvalue>circle</returnvalue>
12225 </para>
12226 <para>
12227 Computes smallest circle enclosing box.
12228 </para>
12229 <para>
12230 <literal>circle(box '(1,1),(0,0)')</literal>
12231 <returnvalue>&lt;(0.5,0.5),0.7071067811865476&gt;</returnvalue>
12232 </para></entry>
12233 </row>
12235 <row>
12236 <entry role="func_table_entry"><para role="func_signature">
12237 <function>circle</function> ( <type>point</type>, <type>double precision</type> )
12238 <returnvalue>circle</returnvalue>
12239 </para>
12240 <para>
12241 Constructs circle from center and radius.
12242 </para>
12243 <para>
12244 <literal>circle(point '(0,0)', 2.0)</literal>
12245 <returnvalue>&lt;(0,0),2&gt;</returnvalue>
12246 </para></entry>
12247 </row>
12249 <row>
12250 <entry role="func_table_entry"><para role="func_signature">
12251 <function>circle</function> ( <type>polygon</type> )
12252 <returnvalue>circle</returnvalue>
12253 </para>
12254 <para>
12255 Converts polygon to circle. The circle's center is the mean of the
12256 positions of the polygon's points, and the radius is the average
12257 distance of the polygon's points from that center.
12258 </para>
12259 <para>
12260 <literal>circle(polygon '((0,0),(1,3),(2,0))')</literal>
12261 <returnvalue>&lt;(1,1),1.6094757082487299&gt;</returnvalue>
12262 </para></entry>
12263 </row>
12265 <row>
12266 <entry role="func_table_entry"><para role="func_signature">
12267 <indexterm>
12268 <primary>line</primary>
12269 </indexterm>
12270 <function>line</function> ( <type>point</type>, <type>point</type> )
12271 <returnvalue>line</returnvalue>
12272 </para>
12273 <para>
12274 Converts two points to the line through them.
12275 </para>
12276 <para>
12277 <literal>line(point '(-1,0)', point '(1,0)')</literal>
12278 <returnvalue>{0,-1,0}</returnvalue>
12279 </para></entry>
12280 </row>
12282 <row>
12283 <entry role="func_table_entry"><para role="func_signature">
12284 <indexterm>
12285 <primary>lseg</primary>
12286 </indexterm>
12287 <function>lseg</function> ( <type>box</type> )
12288 <returnvalue>lseg</returnvalue>
12289 </para>
12290 <para>
12291 Extracts box's diagonal as a line segment.
12292 </para>
12293 <para>
12294 <literal>lseg(box '(1,0),(-1,0)')</literal>
12295 <returnvalue>[(1,0),(-1,0)]</returnvalue>
12296 </para></entry>
12297 </row>
12299 <row>
12300 <entry role="func_table_entry"><para role="func_signature">
12301 <function>lseg</function> ( <type>point</type>, <type>point</type> )
12302 <returnvalue>lseg</returnvalue>
12303 </para>
12304 <para>
12305 Constructs line segment from two endpoints.
12306 </para>
12307 <para>
12308 <literal>lseg(point '(-1,0)', point '(1,0)')</literal>
12309 <returnvalue>[(-1,0),(1,0)]</returnvalue>
12310 </para></entry>
12311 </row>
12313 <row>
12314 <entry role="func_table_entry"><para role="func_signature">
12315 <indexterm>
12316 <primary>path</primary>
12317 </indexterm>
12318 <function>path</function> ( <type>polygon</type> )
12319 <returnvalue>path</returnvalue>
12320 </para>
12321 <para>
12322 Converts polygon to a closed path with the same list of points.
12323 </para>
12324 <para>
12325 <literal>path(polygon '((0,0),(1,1),(2,0))')</literal>
12326 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12327 </para></entry>
12328 </row>
12330 <row>
12331 <entry role="func_table_entry"><para role="func_signature">
12332 <indexterm>
12333 <primary>point</primary>
12334 </indexterm>
12335 <function>point</function> ( <type>double precision</type>, <type>double precision</type> )
12336 <returnvalue>point</returnvalue>
12337 </para>
12338 <para>
12339 Constructs point from its coordinates.
12340 </para>
12341 <para>
12342 <literal>point(23.4, -44.5)</literal>
12343 <returnvalue>(23.4,-44.5)</returnvalue>
12344 </para></entry>
12345 </row>
12347 <row>
12348 <entry role="func_table_entry"><para role="func_signature">
12349 <function>point</function> ( <type>box</type> )
12350 <returnvalue>point</returnvalue>
12351 </para>
12352 <para>
12353 Computes center of box.
12354 </para>
12355 <para>
12356 <literal>point(box '(1,0),(-1,0)')</literal>
12357 <returnvalue>(0,0)</returnvalue>
12358 </para></entry>
12359 </row>
12361 <row>
12362 <entry role="func_table_entry"><para role="func_signature">
12363 <function>point</function> ( <type>circle</type> )
12364 <returnvalue>point</returnvalue>
12365 </para>
12366 <para>
12367 Computes center of circle.
12368 </para>
12369 <para>
12370 <literal>point(circle '&lt;(0,0),2&gt;')</literal>
12371 <returnvalue>(0,0)</returnvalue>
12372 </para></entry>
12373 </row>
12375 <row>
12376 <entry role="func_table_entry"><para role="func_signature">
12377 <function>point</function> ( <type>lseg</type> )
12378 <returnvalue>point</returnvalue>
12379 </para>
12380 <para>
12381 Computes center of line segment.
12382 </para>
12383 <para>
12384 <literal>point(lseg '[(-1,0),(1,0)]')</literal>
12385 <returnvalue>(0,0)</returnvalue>
12386 </para></entry>
12387 </row>
12389 <row>
12390 <entry role="func_table_entry"><para role="func_signature">
12391 <function>point</function> ( <type>polygon</type> )
12392 <returnvalue>point</returnvalue>
12393 </para>
12394 <para>
12395 Computes center of polygon (the mean of the
12396 positions of the polygon's points).
12397 </para>
12398 <para>
12399 <literal>point(polygon '((0,0),(1,1),(2,0))')</literal>
12400 <returnvalue>(1,0.3333333333333333)</returnvalue>
12401 </para></entry>
12402 </row>
12404 <row>
12405 <entry role="func_table_entry"><para role="func_signature">
12406 <indexterm>
12407 <primary>polygon</primary>
12408 </indexterm>
12409 <function>polygon</function> ( <type>box</type> )
12410 <returnvalue>polygon</returnvalue>
12411 </para>
12412 <para>
12413 Converts box to a 4-point polygon.
12414 </para>
12415 <para>
12416 <literal>polygon(box '(1,1),(0,0)')</literal>
12417 <returnvalue>((0,0),(0,1),(1,1),(1,0))</returnvalue>
12418 </para></entry>
12419 </row>
12421 <row>
12422 <entry role="func_table_entry"><para role="func_signature">
12423 <function>polygon</function> ( <type>circle</type> )
12424 <returnvalue>polygon</returnvalue>
12425 </para>
12426 <para>
12427 Converts circle to a 12-point polygon.
12428 </para>
12429 <para>
12430 <literal>polygon(circle '&lt;(0,0),2&gt;')</literal>
12431 <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>
12432 </para></entry>
12433 </row>
12435 <row>
12436 <entry role="func_table_entry"><para role="func_signature">
12437 <function>polygon</function> ( <type>integer</type>, <type>circle</type> )
12438 <returnvalue>polygon</returnvalue>
12439 </para>
12440 <para>
12441 Converts circle to an <replaceable>n</replaceable>-point polygon.
12442 </para>
12443 <para>
12444 <literal>polygon(4, circle '&lt;(3,0),1&gt;')</literal>
12445 <returnvalue>((2,0),&zwsp;(3,1),&zwsp;(4,1.2246063538223773e-16),&zwsp;(3,-1))</returnvalue>
12446 </para></entry>
12447 </row>
12449 <row>
12450 <entry role="func_table_entry"><para role="func_signature">
12451 <function>polygon</function> ( <type>path</type> )
12452 <returnvalue>polygon</returnvalue>
12453 </para>
12454 <para>
12455 Converts closed path to a polygon with the same list of points.
12456 </para>
12457 <para>
12458 <literal>polygon(path '((0,0),(1,1),(2,0))')</literal>
12459 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12460 </para></entry>
12461 </row>
12463 </tbody>
12464 </tgroup>
12465 </table>
12467 <para>
12468 It is possible to access the two component numbers of a <type>point</type>
12469 as though the point were an array with indexes 0 and 1. For example, if
12470 <literal>t.p</literal> is a <type>point</type> column then
12471 <literal>SELECT p[0] FROM t</literal> retrieves the X coordinate and
12472 <literal>UPDATE t SET p[1] = ...</literal> changes the Y coordinate.
12473 In the same way, a value of type <type>box</type> or <type>lseg</type> can be treated
12474 as an array of two <type>point</type> values.
12475 </para>
12477 </sect1>
12480 <sect1 id="functions-net">
12481 <title>Network Address Functions and Operators</title>
12483 <para>
12484 The IP network address types, <type>cidr</type> and <type>inet</type>,
12485 support the usual comparison operators shown in
12486 <xref linkend="functions-comparison-op-table"/>
12487 as well as the specialized operators and functions shown in
12488 <xref linkend="cidr-inet-operators-table"/> and
12489 <xref linkend="cidr-inet-functions-table"/>.
12490 </para>
12492 <para>
12493 Any <type>cidr</type> value can be cast to <type>inet</type> implicitly;
12494 therefore, the operators and functions shown below as operating on
12495 <type>inet</type> also work on <type>cidr</type> values. (Where there are
12496 separate functions for <type>inet</type> and <type>cidr</type>, it is
12497 because the behavior should be different for the two cases.)
12498 Also, it is permitted to cast an <type>inet</type> value
12499 to <type>cidr</type>. When this is done, any bits to the right of the
12500 netmask are silently zeroed to create a valid <type>cidr</type> value.
12501 </para>
12503 <table id="cidr-inet-operators-table">
12504 <title>IP Address Operators</title>
12505 <tgroup cols="1">
12506 <thead>
12507 <row>
12508 <entry role="func_table_entry"><para role="func_signature">
12509 Operator
12510 </para>
12511 <para>
12512 Description
12513 </para>
12514 <para>
12515 Example(s)
12516 </para></entry>
12517 </row>
12518 </thead>
12520 <tbody>
12521 <row>
12522 <entry role="func_table_entry"><para role="func_signature">
12523 <type>inet</type> <literal>&lt;&lt;</literal> <type>inet</type>
12524 <returnvalue>boolean</returnvalue>
12525 </para>
12526 <para>
12527 Is subnet strictly contained by subnet?
12528 This operator, and the next four, test for subnet inclusion. They
12529 consider only the network parts of the two addresses (ignoring any
12530 bits to the right of the netmasks) and determine whether one network
12531 is identical to or a subnet of the other.
12532 </para>
12533 <para>
12534 <literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal>
12535 <returnvalue>t</returnvalue>
12536 </para>
12537 <para>
12538 <literal>inet '192.168.0.5' &lt;&lt; inet '192.168.1/24'</literal>
12539 <returnvalue>f</returnvalue>
12540 </para>
12541 <para>
12542 <literal>inet '192.168.1/24' &lt;&lt; inet '192.168.1/24'</literal>
12543 <returnvalue>f</returnvalue>
12544 </para></entry>
12545 </row>
12547 <row>
12548 <entry role="func_table_entry"><para role="func_signature">
12549 <type>inet</type> <literal>&lt;&lt;=</literal> <type>inet</type>
12550 <returnvalue>boolean</returnvalue>
12551 </para>
12552 <para>
12553 Is subnet contained by or equal to subnet?
12554 </para>
12555 <para>
12556 <literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal>
12557 <returnvalue>t</returnvalue>
12558 </para></entry>
12559 </row>
12561 <row>
12562 <entry role="func_table_entry"><para role="func_signature">
12563 <type>inet</type> <literal>&gt;&gt;</literal> <type>inet</type>
12564 <returnvalue>boolean</returnvalue>
12565 </para>
12566 <para>
12567 Does subnet strictly contain subnet?
12568 </para>
12569 <para>
12570 <literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal>
12571 <returnvalue>t</returnvalue>
12572 </para></entry>
12573 </row>
12575 <row>
12576 <entry role="func_table_entry"><para role="func_signature">
12577 <type>inet</type> <literal>&gt;&gt;=</literal> <type>inet</type>
12578 <returnvalue>boolean</returnvalue>
12579 </para>
12580 <para>
12581 Does subnet contain or equal subnet?
12582 </para>
12583 <para>
12584 <literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal>
12585 <returnvalue>t</returnvalue>
12586 </para></entry>
12587 </row>
12589 <row>
12590 <entry role="func_table_entry"><para role="func_signature">
12591 <type>inet</type> <literal>&amp;&amp;</literal> <type>inet</type>
12592 <returnvalue>boolean</returnvalue>
12593 </para>
12594 <para>
12595 Does either subnet contain or equal the other?
12596 </para>
12597 <para>
12598 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.1.80/28'</literal>
12599 <returnvalue>t</returnvalue>
12600 </para>
12601 <para>
12602 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.2.0/28'</literal>
12603 <returnvalue>f</returnvalue>
12604 </para></entry>
12605 </row>
12607 <row>
12608 <entry role="func_table_entry"><para role="func_signature">
12609 <literal>~</literal> <type>inet</type>
12610 <returnvalue>inet</returnvalue>
12611 </para>
12612 <para>
12613 Computes bitwise NOT.
12614 </para>
12615 <para>
12616 <literal>~ inet '192.168.1.6'</literal>
12617 <returnvalue>63.87.254.249</returnvalue>
12618 </para></entry>
12619 </row>
12621 <row>
12622 <entry role="func_table_entry"><para role="func_signature">
12623 <type>inet</type> <literal>&amp;</literal> <type>inet</type>
12624 <returnvalue>inet</returnvalue>
12625 </para>
12626 <para>
12627 Computes bitwise AND.
12628 </para>
12629 <para>
12630 <literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal>
12631 <returnvalue>0.0.0.6</returnvalue>
12632 </para></entry>
12633 </row>
12635 <row>
12636 <entry role="func_table_entry"><para role="func_signature">
12637 <type>inet</type> <literal>|</literal> <type>inet</type>
12638 <returnvalue>inet</returnvalue>
12639 </para>
12640 <para>
12641 Computes bitwise OR.
12642 </para>
12643 <para>
12644 <literal>inet '192.168.1.6' | inet '0.0.0.255'</literal>
12645 <returnvalue>192.168.1.255</returnvalue>
12646 </para></entry>
12647 </row>
12649 <row>
12650 <entry role="func_table_entry"><para role="func_signature">
12651 <type>inet</type> <literal>+</literal> <type>bigint</type>
12652 <returnvalue>inet</returnvalue>
12653 </para>
12654 <para>
12655 Adds an offset to an address.
12656 </para>
12657 <para>
12658 <literal>inet '192.168.1.6' + 25</literal>
12659 <returnvalue>192.168.1.31</returnvalue>
12660 </para></entry>
12661 </row>
12663 <row>
12664 <entry role="func_table_entry"><para role="func_signature">
12665 <type>bigint</type> <literal>+</literal> <type>inet</type>
12666 <returnvalue>inet</returnvalue>
12667 </para>
12668 <para>
12669 Adds an offset to an address.
12670 </para>
12671 <para>
12672 <literal>200 + inet '::ffff:fff0:1'</literal>
12673 <returnvalue>::ffff:255.240.0.201</returnvalue>
12674 </para></entry>
12675 </row>
12677 <row>
12678 <entry role="func_table_entry"><para role="func_signature">
12679 <type>inet</type> <literal>-</literal> <type>bigint</type>
12680 <returnvalue>inet</returnvalue>
12681 </para>
12682 <para>
12683 Subtracts an offset from an address.
12684 </para>
12685 <para>
12686 <literal>inet '192.168.1.43' - 36</literal>
12687 <returnvalue>192.168.1.7</returnvalue>
12688 </para></entry>
12689 </row>
12691 <row>
12692 <entry role="func_table_entry"><para role="func_signature">
12693 <type>inet</type> <literal>-</literal> <type>inet</type>
12694 <returnvalue>bigint</returnvalue>
12695 </para>
12696 <para>
12697 Computes the difference of two addresses.
12698 </para>
12699 <para>
12700 <literal>inet '192.168.1.43' - inet '192.168.1.19'</literal>
12701 <returnvalue>24</returnvalue>
12702 </para>
12703 <para>
12704 <literal>inet '::1' - inet '::ffff:1'</literal>
12705 <returnvalue>-4294901760</returnvalue>
12706 </para></entry>
12707 </row>
12708 </tbody>
12709 </tgroup>
12710 </table>
12712 <table id="cidr-inet-functions-table">
12713 <title>IP Address Functions</title>
12714 <tgroup cols="1">
12715 <thead>
12716 <row>
12717 <entry role="func_table_entry"><para role="func_signature">
12718 Function
12719 </para>
12720 <para>
12721 Description
12722 </para>
12723 <para>
12724 Example(s)
12725 </para></entry>
12726 </row>
12727 </thead>
12729 <tbody>
12730 <row>
12731 <entry role="func_table_entry"><para role="func_signature">
12732 <indexterm>
12733 <primary>abbrev</primary>
12734 </indexterm>
12735 <function>abbrev</function> ( <type>inet</type> )
12736 <returnvalue>text</returnvalue>
12737 </para>
12738 <para>
12739 Creates an abbreviated display format as text.
12740 (The result is the same as the <type>inet</type> output function
12741 produces; it is <quote>abbreviated</quote> only in comparison to the
12742 result of an explicit cast to <type>text</type>, which for historical
12743 reasons will never suppress the netmask part.)
12744 </para>
12745 <para>
12746 <literal>abbrev(inet '10.1.0.0/32')</literal>
12747 <returnvalue>10.1.0.0</returnvalue>
12748 </para></entry>
12749 </row>
12751 <row>
12752 <entry role="func_table_entry"><para role="func_signature">
12753 <function>abbrev</function> ( <type>cidr</type> )
12754 <returnvalue>text</returnvalue>
12755 </para>
12756 <para>
12757 Creates an abbreviated display format as text.
12758 (The abbreviation consists of dropping all-zero octets to the right
12759 of the netmask; more examples are in
12760 <xref linkend="datatype-net-cidr-table"/>.)
12761 </para>
12762 <para>
12763 <literal>abbrev(cidr '10.1.0.0/16')</literal>
12764 <returnvalue>10.1/16</returnvalue>
12765 </para></entry>
12766 </row>
12768 <row>
12769 <entry role="func_table_entry"><para role="func_signature">
12770 <indexterm>
12771 <primary>broadcast</primary>
12772 </indexterm>
12773 <function>broadcast</function> ( <type>inet</type> )
12774 <returnvalue>inet</returnvalue>
12775 </para>
12776 <para>
12777 Computes the broadcast address for the address's network.
12778 </para>
12779 <para>
12780 <literal>broadcast(inet '192.168.1.5/24')</literal>
12781 <returnvalue>192.168.1.255/24</returnvalue>
12782 </para></entry>
12783 </row>
12785 <row>
12786 <entry role="func_table_entry"><para role="func_signature">
12787 <indexterm>
12788 <primary>family</primary>
12789 </indexterm>
12790 <function>family</function> ( <type>inet</type> )
12791 <returnvalue>integer</returnvalue>
12792 </para>
12793 <para>
12794 Returns the address's family: <literal>4</literal> for IPv4,
12795 <literal>6</literal> for IPv6.
12796 </para>
12797 <para>
12798 <literal>family(inet '::1')</literal>
12799 <returnvalue>6</returnvalue>
12800 </para></entry>
12801 </row>
12803 <row>
12804 <entry role="func_table_entry"><para role="func_signature">
12805 <indexterm>
12806 <primary>host</primary>
12807 </indexterm>
12808 <function>host</function> ( <type>inet</type> )
12809 <returnvalue>text</returnvalue>
12810 </para>
12811 <para>
12812 Returns the IP address as text, ignoring the netmask.
12813 </para>
12814 <para>
12815 <literal>host(inet '192.168.1.0/24')</literal>
12816 <returnvalue>192.168.1.0</returnvalue>
12817 </para></entry>
12818 </row>
12820 <row>
12821 <entry role="func_table_entry"><para role="func_signature">
12822 <indexterm>
12823 <primary>hostmask</primary>
12824 </indexterm>
12825 <function>hostmask</function> ( <type>inet</type> )
12826 <returnvalue>inet</returnvalue>
12827 </para>
12828 <para>
12829 Computes the host mask for the address's network.
12830 </para>
12831 <para>
12832 <literal>hostmask(inet '192.168.23.20/30')</literal>
12833 <returnvalue>0.0.0.3</returnvalue>
12834 </para></entry>
12835 </row>
12837 <row>
12838 <entry role="func_table_entry"><para role="func_signature">
12839 <indexterm>
12840 <primary>inet_merge</primary>
12841 </indexterm>
12842 <function>inet_merge</function> ( <type>inet</type>, <type>inet</type> )
12843 <returnvalue>cidr</returnvalue>
12844 </para>
12845 <para>
12846 Computes the smallest network that includes both of the given networks.
12847 </para>
12848 <para>
12849 <literal>inet_merge(inet '192.168.1.5/24', inet '192.168.2.5/24')</literal>
12850 <returnvalue>192.168.0.0/22</returnvalue>
12851 </para></entry>
12852 </row>
12854 <row>
12855 <entry role="func_table_entry"><para role="func_signature">
12856 <indexterm>
12857 <primary>inet_same_family</primary>
12858 </indexterm>
12859 <function>inet_same_family</function> ( <type>inet</type>, <type>inet</type> )
12860 <returnvalue>boolean</returnvalue>
12861 </para>
12862 <para>
12863 Tests whether the addresses belong to the same IP family.
12864 </para>
12865 <para>
12866 <literal>inet_same_family(inet '192.168.1.5/24', inet '::1')</literal>
12867 <returnvalue>f</returnvalue>
12868 </para></entry>
12869 </row>
12871 <row>
12872 <entry role="func_table_entry"><para role="func_signature">
12873 <indexterm>
12874 <primary>masklen</primary>
12875 </indexterm>
12876 <function>masklen</function> ( <type>inet</type> )
12877 <returnvalue>integer</returnvalue>
12878 </para>
12879 <para>
12880 Returns the netmask length in bits.
12881 </para>
12882 <para>
12883 <literal>masklen(inet '192.168.1.5/24')</literal>
12884 <returnvalue>24</returnvalue>
12885 </para></entry>
12886 </row>
12888 <row>
12889 <entry role="func_table_entry"><para role="func_signature">
12890 <indexterm>
12891 <primary>netmask</primary>
12892 </indexterm>
12893 <function>netmask</function> ( <type>inet</type> )
12894 <returnvalue>inet</returnvalue>
12895 </para>
12896 <para>
12897 Computes the network mask for the address's network.
12898 </para>
12899 <para>
12900 <literal>netmask(inet '192.168.1.5/24')</literal>
12901 <returnvalue>255.255.255.0</returnvalue>
12902 </para></entry>
12903 </row>
12905 <row>
12906 <entry role="func_table_entry"><para role="func_signature">
12907 <indexterm>
12908 <primary>network</primary>
12909 </indexterm>
12910 <function>network</function> ( <type>inet</type> )
12911 <returnvalue>cidr</returnvalue>
12912 </para>
12913 <para>
12914 Returns the network part of the address, zeroing out
12915 whatever is to the right of the netmask.
12916 (This is equivalent to casting the value to <type>cidr</type>.)
12917 </para>
12918 <para>
12919 <literal>network(inet '192.168.1.5/24')</literal>
12920 <returnvalue>192.168.1.0/24</returnvalue>
12921 </para></entry>
12922 </row>
12924 <row>
12925 <entry role="func_table_entry"><para role="func_signature">
12926 <indexterm>
12927 <primary>set_masklen</primary>
12928 </indexterm>
12929 <function>set_masklen</function> ( <type>inet</type>, <type>integer</type> )
12930 <returnvalue>inet</returnvalue>
12931 </para>
12932 <para>
12933 Sets the netmask length for an <type>inet</type> value.
12934 The address part does not change.
12935 </para>
12936 <para>
12937 <literal>set_masklen(inet '192.168.1.5/24', 16)</literal>
12938 <returnvalue>192.168.1.5/16</returnvalue>
12939 </para></entry>
12940 </row>
12942 <row>
12943 <entry role="func_table_entry"><para role="func_signature">
12944 <function>set_masklen</function> ( <type>cidr</type>, <type>integer</type> )
12945 <returnvalue>cidr</returnvalue>
12946 </para>
12947 <para>
12948 Sets the netmask length for a <type>cidr</type> value.
12949 Address bits to the right of the new netmask are set to zero.
12950 </para>
12951 <para>
12952 <literal>set_masklen(cidr '192.168.1.0/24', 16)</literal>
12953 <returnvalue>192.168.0.0/16</returnvalue>
12954 </para></entry>
12955 </row>
12957 <row>
12958 <entry role="func_table_entry"><para role="func_signature">
12959 <indexterm>
12960 <primary>text</primary>
12961 </indexterm>
12962 <function>text</function> ( <type>inet</type> )
12963 <returnvalue>text</returnvalue>
12964 </para>
12965 <para>
12966 Returns the unabbreviated IP address and netmask length as text.
12967 (This has the same result as an explicit cast to <type>text</type>.)
12968 </para>
12969 <para>
12970 <literal>text(inet '192.168.1.5')</literal>
12971 <returnvalue>192.168.1.5/32</returnvalue>
12972 </para></entry>
12973 </row>
12974 </tbody>
12975 </tgroup>
12976 </table>
12978 <tip>
12979 <para>
12980 The <function>abbrev</function>, <function>host</function>,
12981 and <function>text</function> functions are primarily intended to offer
12982 alternative display formats for IP addresses.
12983 </para>
12984 </tip>
12986 <para>
12987 The MAC address types, <type>macaddr</type> and <type>macaddr8</type>,
12988 support the usual comparison operators shown in
12989 <xref linkend="functions-comparison-op-table"/>
12990 as well as the specialized functions shown in
12991 <xref linkend="macaddr-functions-table"/>.
12992 In addition, they support the bitwise logical operators
12993 <literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>
12994 (NOT, AND and OR), just as shown above for IP addresses.
12995 </para>
12997 <table id="macaddr-functions-table">
12998 <title>MAC Address Functions</title>
12999 <tgroup cols="1">
13000 <thead>
13001 <row>
13002 <entry role="func_table_entry"><para role="func_signature">
13003 Function
13004 </para>
13005 <para>
13006 Description
13007 </para>
13008 <para>
13009 Example(s)
13010 </para></entry>
13011 </row>
13012 </thead>
13014 <tbody>
13015 <row>
13016 <entry role="func_table_entry"><para role="func_signature">
13017 <indexterm>
13018 <primary>trunc</primary>
13019 </indexterm>
13020 <function>trunc</function> ( <type>macaddr</type> )
13021 <returnvalue>macaddr</returnvalue>
13022 </para>
13023 <para>
13024 Sets the last 3 bytes of the address to zero. The remaining prefix
13025 can be associated with a particular manufacturer (using data not
13026 included in <productname>PostgreSQL</productname>).
13027 </para>
13028 <para>
13029 <literal>trunc(macaddr '12:34:56:78:90:ab')</literal>
13030 <returnvalue>12:34:56:00:00:00</returnvalue>
13031 </para></entry>
13032 </row>
13034 <row>
13035 <entry role="func_table_entry"><para role="func_signature">
13036 <function>trunc</function> ( <type>macaddr8</type> )
13037 <returnvalue>macaddr8</returnvalue>
13038 </para>
13039 <para>
13040 Sets the last 5 bytes of the address to zero. The remaining prefix
13041 can be associated with a particular manufacturer (using data not
13042 included in <productname>PostgreSQL</productname>).
13043 </para>
13044 <para>
13045 <literal>trunc(macaddr8 '12:34:56:78:90:ab:cd:ef')</literal>
13046 <returnvalue>12:34:56:00:00:00:00:00</returnvalue>
13047 </para></entry>
13048 </row>
13050 <row>
13051 <entry role="func_table_entry"><para role="func_signature">
13052 <indexterm>
13053 <primary>macaddr8_set7bit</primary>
13054 </indexterm>
13055 <function>macaddr8_set7bit</function> ( <type>macaddr8</type> )
13056 <returnvalue>macaddr8</returnvalue>
13057 </para>
13058 <para>
13059 Sets the 7th bit of the address to one, creating what is known as
13060 modified EUI-64, for inclusion in an IPv6 address.
13061 </para>
13062 <para>
13063 <literal>macaddr8_set7bit(macaddr8 '00:34:56:ab:cd:ef')</literal>
13064 <returnvalue>02:34:56:ff:fe:ab:cd:ef</returnvalue>
13065 </para></entry>
13066 </row>
13067 </tbody>
13068 </tgroup>
13069 </table>
13071 </sect1>
13074 <sect1 id="functions-textsearch">
13075 <title>Text Search Functions and Operators</title>
13077 <indexterm zone="datatype-textsearch">
13078 <primary>full text search</primary>
13079 <secondary>functions and operators</secondary>
13080 </indexterm>
13082 <indexterm zone="datatype-textsearch">
13083 <primary>text search</primary>
13084 <secondary>functions and operators</secondary>
13085 </indexterm>
13087 <para>
13088 <xref linkend="textsearch-operators-table"/>,
13089 <xref linkend="textsearch-functions-table"/> and
13090 <xref linkend="textsearch-functions-debug-table"/>
13091 summarize the functions and operators that are provided
13092 for full text searching. See <xref linkend="textsearch"/> for a detailed
13093 explanation of <productname>PostgreSQL</productname>'s text search
13094 facility.
13095 </para>
13097 <table id="textsearch-operators-table">
13098 <title>Text Search Operators</title>
13099 <tgroup cols="1">
13100 <thead>
13101 <row>
13102 <entry role="func_table_entry"><para role="func_signature">
13103 Operator
13104 </para>
13105 <para>
13106 Description
13107 </para>
13108 <para>
13109 Example(s)
13110 </para></entry>
13111 </row>
13112 </thead>
13114 <tbody>
13115 <row>
13116 <entry role="func_table_entry"><para role="func_signature">
13117 <type>tsvector</type> <literal>@@</literal> <type>tsquery</type>
13118 <returnvalue>boolean</returnvalue>
13119 </para>
13120 <para role="func_signature">
13121 <type>tsquery</type> <literal>@@</literal> <type>tsvector</type>
13122 <returnvalue>boolean</returnvalue>
13123 </para>
13124 <para>
13125 Does <type>tsvector</type> match <type>tsquery</type>?
13126 (The arguments can be given in either order.)
13127 </para>
13128 <para>
13129 <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal>
13130 <returnvalue>t</returnvalue>
13131 </para></entry>
13132 </row>
13134 <row>
13135 <entry role="func_table_entry"><para role="func_signature">
13136 <type>text</type> <literal>@@</literal> <type>tsquery</type>
13137 <returnvalue>boolean</returnvalue>
13138 </para>
13139 <para>
13140 Does text string, after implicit invocation
13141 of <function>to_tsvector()</function>, match <type>tsquery</type>?
13142 </para>
13143 <para>
13144 <literal>'fat cats ate rats' @@ to_tsquery('cat &amp; rat')</literal>
13145 <returnvalue>t</returnvalue>
13146 </para></entry>
13147 </row>
13149 <row>
13150 <entry role="func_table_entry"><para role="func_signature">
13151 <type>tsvector</type> <literal>||</literal> <type>tsvector</type>
13152 <returnvalue>tsvector</returnvalue>
13153 </para>
13154 <para>
13155 Concatenates two <type>tsvector</type>s. If both inputs contain
13156 lexeme positions, the second input's positions are adjusted
13157 accordingly.
13158 </para>
13159 <para>
13160 <literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal>
13161 <returnvalue>'a':1 'b':2,5 'c':3 'd':4</returnvalue>
13162 </para></entry>
13163 </row>
13165 <row>
13166 <entry role="func_table_entry"><para role="func_signature">
13167 <type>tsquery</type> <literal>&amp;&amp;</literal> <type>tsquery</type>
13168 <returnvalue>tsquery</returnvalue>
13169 </para>
13170 <para>
13171 ANDs two <type>tsquery</type>s together, producing a query that
13172 matches documents that match both input queries.
13173 </para>
13174 <para>
13175 <literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal>
13176 <returnvalue>( 'fat' | 'rat' ) &amp; 'cat'</returnvalue>
13177 </para></entry>
13178 </row>
13180 <row>
13181 <entry role="func_table_entry"><para role="func_signature">
13182 <type>tsquery</type> <literal>||</literal> <type>tsquery</type>
13183 <returnvalue>tsquery</returnvalue>
13184 </para>
13185 <para>
13186 ORs two <type>tsquery</type>s together, producing a query that
13187 matches documents that match either input query.
13188 </para>
13189 <para>
13190 <literal>'fat | rat'::tsquery || 'cat'::tsquery</literal>
13191 <returnvalue>'fat' | 'rat' | 'cat'</returnvalue>
13192 </para></entry>
13193 </row>
13195 <row>
13196 <entry role="func_table_entry"><para role="func_signature">
13197 <literal>!!</literal> <type>tsquery</type>
13198 <returnvalue>tsquery</returnvalue>
13199 </para>
13200 <para>
13201 Negates a <type>tsquery</type>, producing a query that matches
13202 documents that do not match the input query.
13203 </para>
13204 <para>
13205 <literal>!! 'cat'::tsquery</literal>
13206 <returnvalue>!'cat'</returnvalue>
13207 </para></entry>
13208 </row>
13210 <row>
13211 <entry role="func_table_entry"><para role="func_signature">
13212 <type>tsquery</type> <literal>&lt;-&gt;</literal> <type>tsquery</type>
13213 <returnvalue>tsquery</returnvalue>
13214 </para>
13215 <para>
13216 Constructs a phrase query, which matches if the two input queries
13217 match at successive lexemes.
13218 </para>
13219 <para>
13220 <literal>to_tsquery('fat') &lt;-&gt; to_tsquery('rat')</literal>
13221 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
13222 </para></entry>
13223 </row>
13225 <row>
13226 <entry role="func_table_entry"><para role="func_signature">
13227 <type>tsquery</type> <literal>@&gt;</literal> <type>tsquery</type>
13228 <returnvalue>boolean</returnvalue>
13229 </para>
13230 <para>
13231 Does first <type>tsquery</type> contain the second? (This considers
13232 only whether all the lexemes appearing in one query appear in the
13233 other, ignoring the combining operators.)
13234 </para>
13235 <para>
13236 <literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal>
13237 <returnvalue>f</returnvalue>
13238 </para></entry>
13239 </row>
13241 <row>
13242 <entry role="func_table_entry"><para role="func_signature">
13243 <type>tsquery</type> <literal>&lt;@</literal> <type>tsquery</type>
13244 <returnvalue>boolean</returnvalue>
13245 </para>
13246 <para>
13247 Is first <type>tsquery</type> contained in the second? (This
13248 considers only whether all the lexemes appearing in one query appear
13249 in the other, ignoring the combining operators.)
13250 </para>
13251 <para>
13252 <literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal>
13253 <returnvalue>t</returnvalue>
13254 </para>
13255 <para>
13256 <literal>'cat'::tsquery &lt;@ '!cat &amp; rat'::tsquery</literal>
13257 <returnvalue>t</returnvalue>
13258 </para></entry>
13259 </row>
13260 </tbody>
13261 </tgroup>
13262 </table>
13264 <para>
13265 In addition to these specialized operators, the usual comparison
13266 operators shown in <xref linkend="functions-comparison-op-table"/> are
13267 available for types <type>tsvector</type> and <type>tsquery</type>.
13268 These are not very
13269 useful for text searching but allow, for example, unique indexes to be
13270 built on columns of these types.
13271 </para>
13273 <table id="textsearch-functions-table">
13274 <title>Text Search Functions</title>
13275 <tgroup cols="1">
13276 <thead>
13277 <row>
13278 <entry role="func_table_entry"><para role="func_signature">
13279 Function
13280 </para>
13281 <para>
13282 Description
13283 </para>
13284 <para>
13285 Example(s)
13286 </para></entry>
13287 </row>
13288 </thead>
13290 <tbody>
13291 <row>
13292 <entry role="func_table_entry"><para role="func_signature">
13293 <indexterm>
13294 <primary>array_to_tsvector</primary>
13295 </indexterm>
13296 <function>array_to_tsvector</function> ( <type>text[]</type> )
13297 <returnvalue>tsvector</returnvalue>
13298 </para>
13299 <para>
13300 Converts an array of text strings to a <type>tsvector</type>.
13301 The given strings are used as lexemes as-is, without further
13302 processing. Array elements must not be empty strings
13303 or <literal>NULL</literal>.
13304 </para>
13305 <para>
13306 <literal>array_to_tsvector('{fat,cat,rat}'::text[])</literal>
13307 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13308 </para></entry>
13309 </row>
13311 <row>
13312 <entry role="func_table_entry"><para role="func_signature">
13313 <indexterm>
13314 <primary>get_current_ts_config</primary>
13315 </indexterm>
13316 <function>get_current_ts_config</function> ( )
13317 <returnvalue>regconfig</returnvalue>
13318 </para>
13319 <para>
13320 Returns the OID of the current default text search configuration
13321 (as set by <xref linkend="guc-default-text-search-config"/>).
13322 </para>
13323 <para>
13324 <literal>get_current_ts_config()</literal>
13325 <returnvalue>english</returnvalue>
13326 </para></entry>
13327 </row>
13329 <row>
13330 <entry role="func_table_entry"><para role="func_signature">
13331 <indexterm>
13332 <primary>length</primary>
13333 </indexterm>
13334 <function>length</function> ( <type>tsvector</type> )
13335 <returnvalue>integer</returnvalue>
13336 </para>
13337 <para>
13338 Returns the number of lexemes in the <type>tsvector</type>.
13339 </para>
13340 <para>
13341 <literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13342 <returnvalue>3</returnvalue>
13343 </para></entry>
13344 </row>
13346 <row>
13347 <entry role="func_table_entry"><para role="func_signature">
13348 <indexterm>
13349 <primary>numnode</primary>
13350 </indexterm>
13351 <function>numnode</function> ( <type>tsquery</type> )
13352 <returnvalue>integer</returnvalue>
13353 </para>
13354 <para>
13355 Returns the number of lexemes plus operators in
13356 the <type>tsquery</type>.
13357 </para>
13358 <para>
13359 <literal>numnode('(fat &amp; rat) | cat'::tsquery)</literal>
13360 <returnvalue>5</returnvalue>
13361 </para></entry>
13362 </row>
13364 <row>
13365 <entry role="func_table_entry"><para role="func_signature">
13366 <indexterm>
13367 <primary>plainto_tsquery</primary>
13368 </indexterm>
13369 <function>plainto_tsquery</function> (
13370 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13371 <parameter>query</parameter> <type>text</type> )
13372 <returnvalue>tsquery</returnvalue>
13373 </para>
13374 <para>
13375 Converts text to a <type>tsquery</type>, normalizing words according to
13376 the specified or default configuration. Any punctuation in the string
13377 is ignored (it does not determine query operators). The resulting
13378 query matches documents containing all non-stopwords in the text.
13379 </para>
13380 <para>
13381 <literal>plainto_tsquery('english', 'The Fat Rats')</literal>
13382 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13383 </para></entry>
13384 </row>
13386 <row>
13387 <entry role="func_table_entry"><para role="func_signature">
13388 <indexterm>
13389 <primary>phraseto_tsquery</primary>
13390 </indexterm>
13391 <function>phraseto_tsquery</function> (
13392 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13393 <parameter>query</parameter> <type>text</type> )
13394 <returnvalue>tsquery</returnvalue>
13395 </para>
13396 <para>
13397 Converts text to a <type>tsquery</type>, normalizing words according to
13398 the specified or default configuration. Any punctuation in the string
13399 is ignored (it does not determine query operators). The resulting
13400 query matches phrases containing all non-stopwords in the text.
13401 </para>
13402 <para>
13403 <literal>phraseto_tsquery('english', 'The Fat Rats')</literal>
13404 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
13405 </para>
13406 <para>
13407 <literal>phraseto_tsquery('english', 'The Cat and Rats')</literal>
13408 <returnvalue>'cat' &lt;2&gt; 'rat'</returnvalue>
13409 </para></entry>
13410 </row>
13412 <row>
13413 <entry role="func_table_entry"><para role="func_signature">
13414 <indexterm>
13415 <primary>websearch_to_tsquery</primary>
13416 </indexterm>
13417 <function>websearch_to_tsquery</function> (
13418 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13419 <parameter>query</parameter> <type>text</type> )
13420 <returnvalue>tsquery</returnvalue>
13421 </para>
13422 <para>
13423 Converts text to a <type>tsquery</type>, normalizing words according
13424 to the specified or default configuration. Quoted word sequences are
13425 converted to phrase tests. The word <quote>or</quote> is understood
13426 as producing an OR operator, and a dash produces a NOT operator;
13427 other punctuation is ignored.
13428 This approximates the behavior of some common web search tools.
13429 </para>
13430 <para>
13431 <literal>websearch_to_tsquery('english', '"fat rat" or cat dog')</literal>
13432 <returnvalue>'fat' &lt;-&gt; 'rat' | 'cat' &amp; 'dog'</returnvalue>
13433 </para></entry>
13434 </row>
13436 <row>
13437 <entry role="func_table_entry"><para role="func_signature">
13438 <indexterm>
13439 <primary>querytree</primary>
13440 </indexterm>
13441 <function>querytree</function> ( <type>tsquery</type> )
13442 <returnvalue>text</returnvalue>
13443 </para>
13444 <para>
13445 Produces a representation of the indexable portion of
13446 a <type>tsquery</type>. A result that is empty or
13447 just <literal>T</literal> indicates a non-indexable query.
13448 </para>
13449 <para>
13450 <literal>querytree('foo &amp; ! bar'::tsquery)</literal>
13451 <returnvalue>'foo'</returnvalue>
13452 </para></entry>
13453 </row>
13455 <row>
13456 <entry role="func_table_entry"><para role="func_signature">
13457 <indexterm>
13458 <primary>setweight</primary>
13459 </indexterm>
13460 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type> )
13461 <returnvalue>tsvector</returnvalue>
13462 </para>
13463 <para>
13464 Assigns the specified <parameter>weight</parameter> to each element
13465 of the <parameter>vector</parameter>.
13466 </para>
13467 <para>
13468 <literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal>
13469 <returnvalue>'cat':3A 'fat':2A,4A 'rat':5A</returnvalue>
13470 </para></entry>
13471 </row>
13473 <row>
13474 <entry role="func_table_entry"><para role="func_signature">
13475 <indexterm>
13476 <primary>setweight</primary>
13477 <secondary>setweight for specific lexeme(s)</secondary>
13478 </indexterm>
13479 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13480 <returnvalue>tsvector</returnvalue>
13481 </para>
13482 <para>
13483 Assigns the specified <parameter>weight</parameter> to elements
13484 of the <parameter>vector</parameter> that are listed
13485 in <parameter>lexemes</parameter>.
13486 The strings in <parameter>lexemes</parameter> are taken as lexemes
13487 as-is, without further processing. Strings that do not match any
13488 lexeme in <parameter>vector</parameter> are ignored.
13489 </para>
13490 <para>
13491 <literal>setweight('fat:2,4 cat:3 rat:5,6B'::tsvector, 'A', '{cat,rat}')</literal>
13492 <returnvalue>'cat':3A 'fat':2,4 'rat':5A,6A</returnvalue>
13493 </para></entry>
13494 </row>
13496 <row>
13497 <entry role="func_table_entry"><para role="func_signature">
13498 <indexterm>
13499 <primary>strip</primary>
13500 </indexterm>
13501 <function>strip</function> ( <type>tsvector</type> )
13502 <returnvalue>tsvector</returnvalue>
13503 </para>
13504 <para>
13505 Removes positions and weights from the <type>tsvector</type>.
13506 </para>
13507 <para>
13508 <literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13509 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13510 </para></entry>
13511 </row>
13513 <row>
13514 <entry role="func_table_entry"><para role="func_signature">
13515 <indexterm>
13516 <primary>to_tsquery</primary>
13517 </indexterm>
13518 <function>to_tsquery</function> (
13519 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13520 <parameter>query</parameter> <type>text</type> )
13521 <returnvalue>tsquery</returnvalue>
13522 </para>
13523 <para>
13524 Converts text to a <type>tsquery</type>, normalizing words according to
13525 the specified or default configuration. The words must be combined
13526 by valid <type>tsquery</type> operators.
13527 </para>
13528 <para>
13529 <literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal>
13530 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13531 </para></entry>
13532 </row>
13534 <row>
13535 <entry role="func_table_entry"><para role="func_signature">
13536 <indexterm>
13537 <primary>to_tsvector</primary>
13538 </indexterm>
13539 <function>to_tsvector</function> (
13540 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13541 <parameter>document</parameter> <type>text</type> )
13542 <returnvalue>tsvector</returnvalue>
13543 </para>
13544 <para>
13545 Converts text to a <type>tsvector</type>, normalizing words according
13546 to the specified or default configuration. Position information is
13547 included in the result.
13548 </para>
13549 <para>
13550 <literal>to_tsvector('english', 'The Fat Rats')</literal>
13551 <returnvalue>'fat':2 'rat':3</returnvalue>
13552 </para></entry>
13553 </row>
13555 <row>
13556 <entry role="func_table_entry"><para role="func_signature">
13557 <function>to_tsvector</function> (
13558 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13559 <parameter>document</parameter> <type>json</type> )
13560 <returnvalue>tsvector</returnvalue>
13561 </para>
13562 <para role="func_signature">
13563 <function>to_tsvector</function> (
13564 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13565 <parameter>document</parameter> <type>jsonb</type> )
13566 <returnvalue>tsvector</returnvalue>
13567 </para>
13568 <para>
13569 Converts each string value in the JSON document to
13570 a <type>tsvector</type>, normalizing words according to the specified
13571 or default configuration. The results are then concatenated in
13572 document order to produce the output. Position information is
13573 generated as though one stopword exists between each pair of string
13574 values. (Beware that <quote>document order</quote> of the fields of a
13575 JSON object is implementation-dependent when the input
13576 is <type>jsonb</type>; observe the difference in the examples.)
13577 </para>
13578 <para>
13579 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::json)</literal>
13580 <returnvalue>'dog':5 'fat':2 'rat':3</returnvalue>
13581 </para>
13582 <para>
13583 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::jsonb)</literal>
13584 <returnvalue>'dog':1 'fat':4 'rat':5</returnvalue>
13585 </para></entry>
13586 </row>
13588 <row>
13589 <entry role="func_table_entry"><para role="func_signature">
13590 <indexterm>
13591 <primary>json_to_tsvector</primary>
13592 </indexterm>
13593 <function>json_to_tsvector</function> (
13594 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13595 <parameter>document</parameter> <type>json</type>,
13596 <parameter>filter</parameter> <type>jsonb</type> )
13597 <returnvalue>tsvector</returnvalue>
13598 </para>
13599 <para role="func_signature">
13600 <indexterm>
13601 <primary>jsonb_to_tsvector</primary>
13602 </indexterm>
13603 <function>jsonb_to_tsvector</function> (
13604 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13605 <parameter>document</parameter> <type>jsonb</type>,
13606 <parameter>filter</parameter> <type>jsonb</type> )
13607 <returnvalue>tsvector</returnvalue>
13608 </para>
13609 <para>
13610 Selects each item in the JSON document that is requested by
13611 the <parameter>filter</parameter> and converts each one to
13612 a <type>tsvector</type>, normalizing words according to the specified
13613 or default configuration. The results are then concatenated in
13614 document order to produce the output. Position information is
13615 generated as though one stopword exists between each pair of selected
13616 items. (Beware that <quote>document order</quote> of the fields of a
13617 JSON object is implementation-dependent when the input
13618 is <type>jsonb</type>.)
13619 The <parameter>filter</parameter> must be a <type>jsonb</type>
13620 array containing zero or more of these keywords:
13621 <literal>"string"</literal> (to include all string values),
13622 <literal>"numeric"</literal> (to include all numeric values),
13623 <literal>"boolean"</literal> (to include all boolean values),
13624 <literal>"key"</literal> (to include all keys), or
13625 <literal>"all"</literal> (to include all the above).
13626 As a special case, the <parameter>filter</parameter> can also be a
13627 simple JSON value that is one of these keywords.
13628 </para>
13629 <para>
13630 <literal>json_to_tsvector('english', '{"a": "The Fat Rats", "b": 123}'::json, '["string", "numeric"]')</literal>
13631 <returnvalue>'123':5 'fat':2 'rat':3</returnvalue>
13632 </para>
13633 <para>
13634 <literal>json_to_tsvector('english', '{"cat": "The Fat Rats", "dog": 123}'::json, '"all"')</literal>
13635 <returnvalue>'123':9 'cat':1 'dog':7 'fat':4 'rat':5</returnvalue>
13636 </para></entry>
13637 </row>
13639 <row>
13640 <entry role="func_table_entry"><para role="func_signature">
13641 <indexterm>
13642 <primary>ts_delete</primary>
13643 </indexterm>
13644 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexeme</parameter> <type>text</type> )
13645 <returnvalue>tsvector</returnvalue>
13646 </para>
13647 <para>
13648 Removes any occurrence of the given <parameter>lexeme</parameter>
13649 from the <parameter>vector</parameter>.
13650 The <parameter>lexeme</parameter> string is treated as a lexeme as-is,
13651 without further processing.
13652 </para>
13653 <para>
13654 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, 'fat')</literal>
13655 <returnvalue>'cat':3 'rat':5A</returnvalue>
13656 </para></entry>
13657 </row>
13659 <row>
13660 <entry role="func_table_entry"><para role="func_signature">
13661 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13662 <returnvalue>tsvector</returnvalue>
13663 </para>
13664 <para>
13665 Removes any occurrences of the lexemes
13666 in <parameter>lexemes</parameter>
13667 from the <parameter>vector</parameter>.
13668 The strings in <parameter>lexemes</parameter> are taken as lexemes
13669 as-is, without further processing. Strings that do not match any
13670 lexeme in <parameter>vector</parameter> are ignored.
13671 </para>
13672 <para>
13673 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, ARRAY['fat','rat'])</literal>
13674 <returnvalue>'cat':3</returnvalue>
13675 </para></entry>
13676 </row>
13678 <row>
13679 <entry role="func_table_entry"><para role="func_signature">
13680 <indexterm>
13681 <primary>ts_filter</primary>
13682 </indexterm>
13683 <function>ts_filter</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weights</parameter> <type>"char"[]</type> )
13684 <returnvalue>tsvector</returnvalue>
13685 </para>
13686 <para>
13687 Selects only elements with the given <parameter>weights</parameter>
13688 from the <parameter>vector</parameter>.
13689 </para>
13690 <para>
13691 <literal>ts_filter('fat:2,4 cat:3b,7c rat:5A'::tsvector, '{a,b}')</literal>
13692 <returnvalue>'cat':3B 'rat':5A</returnvalue>
13693 </para></entry>
13694 </row>
13696 <row>
13697 <entry role="func_table_entry"><para role="func_signature">
13698 <indexterm>
13699 <primary>ts_headline</primary>
13700 </indexterm>
13701 <function>ts_headline</function> (
13702 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13703 <parameter>document</parameter> <type>text</type>,
13704 <parameter>query</parameter> <type>tsquery</type>
13705 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13706 <returnvalue>text</returnvalue>
13707 </para>
13708 <para>
13709 Displays, in an abbreviated form, the match(es) for
13710 the <parameter>query</parameter> in
13711 the <parameter>document</parameter>, which must be raw text not
13712 a <type>tsvector</type>. Words in the document are normalized
13713 according to the specified or default configuration before matching to
13714 the query. Use of this function is discussed in
13715 <xref linkend="textsearch-headline"/>, which also describes the
13716 available <parameter>options</parameter>.
13717 </para>
13718 <para>
13719 <literal>ts_headline('The fat cat ate the rat.', 'cat')</literal>
13720 <returnvalue>The fat &lt;b&gt;cat&lt;/b&gt; ate the rat.</returnvalue>
13721 </para></entry>
13722 </row>
13724 <row>
13725 <entry role="func_table_entry"><para role="func_signature">
13726 <function>ts_headline</function> (
13727 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13728 <parameter>document</parameter> <type>json</type>,
13729 <parameter>query</parameter> <type>tsquery</type>
13730 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13731 <returnvalue>text</returnvalue>
13732 </para>
13733 <para role="func_signature">
13734 <function>ts_headline</function> (
13735 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13736 <parameter>document</parameter> <type>jsonb</type>,
13737 <parameter>query</parameter> <type>tsquery</type>
13738 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13739 <returnvalue>text</returnvalue>
13740 </para>
13741 <para>
13742 Displays, in an abbreviated form, match(es) for
13743 the <parameter>query</parameter> that occur in string values
13744 within the JSON <parameter>document</parameter>.
13745 See <xref linkend="textsearch-headline"/> for more details.
13746 </para>
13747 <para>
13748 <literal>ts_headline('{"cat":"raining cats and dogs"}'::jsonb, 'cat')</literal>
13749 <returnvalue>{"cat": "raining &lt;b&gt;cats&lt;/b&gt; and dogs"}</returnvalue>
13750 </para></entry>
13751 </row>
13753 <row>
13754 <entry role="func_table_entry"><para role="func_signature">
13755 <indexterm>
13756 <primary>ts_rank</primary>
13757 </indexterm>
13758 <function>ts_rank</function> (
13759 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13760 <parameter>vector</parameter> <type>tsvector</type>,
13761 <parameter>query</parameter> <type>tsquery</type>
13762 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13763 <returnvalue>real</returnvalue>
13764 </para>
13765 <para>
13766 Computes a score showing how well
13767 the <parameter>vector</parameter> matches
13768 the <parameter>query</parameter>. See
13769 <xref linkend="textsearch-ranking"/> for details.
13770 </para>
13771 <para>
13772 <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')</literal>
13773 <returnvalue>0.06079271</returnvalue>
13774 </para></entry>
13775 </row>
13777 <row>
13778 <entry role="func_table_entry"><para role="func_signature">
13779 <indexterm>
13780 <primary>ts_rank_cd</primary>
13781 </indexterm>
13782 <function>ts_rank_cd</function> (
13783 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13784 <parameter>vector</parameter> <type>tsvector</type>,
13785 <parameter>query</parameter> <type>tsquery</type>
13786 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13787 <returnvalue>real</returnvalue>
13788 </para>
13789 <para>
13790 Computes a score showing how well
13791 the <parameter>vector</parameter> matches
13792 the <parameter>query</parameter>, using a cover density
13793 algorithm. See <xref linkend="textsearch-ranking"/> for details.
13794 </para>
13795 <para>
13796 <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')</literal>
13797 <returnvalue>0.1</returnvalue>
13798 </para></entry>
13799 </row>
13801 <row>
13802 <entry role="func_table_entry"><para role="func_signature">
13803 <indexterm>
13804 <primary>ts_rewrite</primary>
13805 </indexterm>
13806 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13807 <parameter>target</parameter> <type>tsquery</type>,
13808 <parameter>substitute</parameter> <type>tsquery</type> )
13809 <returnvalue>tsquery</returnvalue>
13810 </para>
13811 <para>
13812 Replaces occurrences of <parameter>target</parameter>
13813 with <parameter>substitute</parameter>
13814 within the <parameter>query</parameter>.
13815 See <xref linkend="textsearch-query-rewriting"/> for details.
13816 </para>
13817 <para>
13818 <literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal>
13819 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13820 </para></entry>
13821 </row>
13823 <row>
13824 <entry role="func_table_entry"><para role="func_signature">
13825 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13826 <parameter>select</parameter> <type>text</type> )
13827 <returnvalue>tsquery</returnvalue>
13828 </para>
13829 <para>
13830 Replaces portions of the <parameter>query</parameter> according to
13831 target(s) and substitute(s) obtained by executing
13832 a <command>SELECT</command> command.
13833 See <xref linkend="textsearch-query-rewriting"/> for details.
13834 </para>
13835 <para>
13836 <literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal>
13837 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13838 </para></entry>
13839 </row>
13841 <row>
13842 <entry role="func_table_entry"><para role="func_signature">
13843 <indexterm>
13844 <primary>tsquery_phrase</primary>
13845 </indexterm>
13846 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type> )
13847 <returnvalue>tsquery</returnvalue>
13848 </para>
13849 <para>
13850 Constructs a phrase query that searches
13851 for matches of <parameter>query1</parameter>
13852 and <parameter>query2</parameter> at successive lexemes (same
13853 as <literal>&lt;-&gt;</literal> operator).
13854 </para>
13855 <para>
13856 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))</literal>
13857 <returnvalue>'fat' &lt;-&gt; 'cat'</returnvalue>
13858 </para></entry>
13859 </row>
13861 <row>
13862 <entry role="func_table_entry"><para role="func_signature">
13863 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type>, <parameter>distance</parameter> <type>integer</type> )
13864 <returnvalue>tsquery</returnvalue>
13865 </para>
13866 <para>
13867 Constructs a phrase query that searches
13868 for matches of <parameter>query1</parameter> and
13869 <parameter>query2</parameter> that occur exactly
13870 <parameter>distance</parameter> lexemes apart.
13871 </para>
13872 <para>
13873 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'), 10)</literal>
13874 <returnvalue>'fat' &lt;10&gt; 'cat'</returnvalue>
13875 </para></entry>
13876 </row>
13878 <row>
13879 <entry role="func_table_entry"><para role="func_signature">
13880 <indexterm>
13881 <primary>tsvector_to_array</primary>
13882 </indexterm>
13883 <function>tsvector_to_array</function> ( <type>tsvector</type> )
13884 <returnvalue>text[]</returnvalue>
13885 </para>
13886 <para>
13887 Converts a <type>tsvector</type> to an array of lexemes.
13888 </para>
13889 <para>
13890 <literal>tsvector_to_array('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13891 <returnvalue>{cat,fat,rat}</returnvalue>
13892 </para></entry>
13893 </row>
13895 <row>
13896 <entry role="func_table_entry"><para role="func_signature">
13897 <indexterm>
13898 <primary>unnest</primary>
13899 <secondary>for tsvector</secondary>
13900 </indexterm>
13901 <function>unnest</function> ( <type>tsvector</type> )
13902 <returnvalue>setof record</returnvalue>
13903 ( <parameter>lexeme</parameter> <type>text</type>,
13904 <parameter>positions</parameter> <type>smallint[]</type>,
13905 <parameter>weights</parameter> <type>text</type> )
13906 </para>
13907 <para>
13908 Expands a <type>tsvector</type> into a set of rows, one per lexeme.
13909 </para>
13910 <para>
13911 <literal>select * from unnest('cat:3 fat:2,4 rat:5A'::tsvector)</literal>
13912 <returnvalue></returnvalue>
13913 <programlisting>
13914 lexeme | positions | weights
13915 --------+-----------+---------
13916 cat | {3} | {D}
13917 fat | {2,4} | {D,D}
13918 rat | {5} | {A}
13919 </programlisting>
13920 </para></entry>
13921 </row>
13922 </tbody>
13923 </tgroup>
13924 </table>
13926 <note>
13927 <para>
13928 All the text search functions that accept an optional <type>regconfig</type>
13929 argument will use the configuration specified by
13930 <xref linkend="guc-default-text-search-config"/>
13931 when that argument is omitted.
13932 </para>
13933 </note>
13935 <para>
13936 The functions in
13937 <xref linkend="textsearch-functions-debug-table"/>
13938 are listed separately because they are not usually used in everyday text
13939 searching operations. They are primarily helpful for development and
13940 debugging of new text search configurations.
13941 </para>
13943 <table id="textsearch-functions-debug-table">
13944 <title>Text Search Debugging Functions</title>
13945 <tgroup cols="1">
13946 <thead>
13947 <row>
13948 <entry role="func_table_entry"><para role="func_signature">
13949 Function
13950 </para>
13951 <para>
13952 Description
13953 </para>
13954 <para>
13955 Example(s)
13956 </para></entry>
13957 </row>
13958 </thead>
13960 <tbody>
13961 <row>
13962 <entry role="func_table_entry"><para role="func_signature">
13963 <indexterm>
13964 <primary>ts_debug</primary>
13965 </indexterm>
13966 <function>ts_debug</function> (
13967 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13968 <parameter>document</parameter> <type>text</type> )
13969 <returnvalue>setof record</returnvalue>
13970 ( <parameter>alias</parameter> <type>text</type>,
13971 <parameter>description</parameter> <type>text</type>,
13972 <parameter>token</parameter> <type>text</type>,
13973 <parameter>dictionaries</parameter> <type>regdictionary[]</type>,
13974 <parameter>dictionary</parameter> <type>regdictionary</type>,
13975 <parameter>lexemes</parameter> <type>text[]</type> )
13976 </para>
13977 <para>
13978 Extracts and normalizes tokens from
13979 the <parameter>document</parameter> according to the specified or
13980 default text search configuration, and returns information about how
13981 each token was processed.
13982 See <xref linkend="textsearch-configuration-testing"/> for details.
13983 </para>
13984 <para>
13985 <literal>ts_debug('english', 'The Brightest supernovaes')</literal>
13986 <returnvalue>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</returnvalue>
13987 </para></entry>
13988 </row>
13990 <row>
13991 <entry role="func_table_entry"><para role="func_signature">
13992 <indexterm>
13993 <primary>ts_lexize</primary>
13994 </indexterm>
13995 <function>ts_lexize</function> ( <parameter>dict</parameter> <type>regdictionary</type>, <parameter>token</parameter> <type>text</type> )
13996 <returnvalue>text[]</returnvalue>
13997 </para>
13998 <para>
13999 Returns an array of replacement lexemes if the input token is known to
14000 the dictionary, or an empty array if the token is known to the
14001 dictionary but it is a stop word, or NULL if it is not a known word.
14002 See <xref linkend="textsearch-dictionary-testing"/> for details.
14003 </para>
14004 <para>
14005 <literal>ts_lexize('english_stem', 'stars')</literal>
14006 <returnvalue>{star}</returnvalue>
14007 </para></entry>
14008 </row>
14010 <row>
14011 <entry role="func_table_entry"><para role="func_signature">
14012 <indexterm>
14013 <primary>ts_parse</primary>
14014 </indexterm>
14015 <function>ts_parse</function> ( <parameter>parser_name</parameter> <type>text</type>,
14016 <parameter>document</parameter> <type>text</type> )
14017 <returnvalue>setof record</returnvalue>
14018 ( <parameter>tokid</parameter> <type>integer</type>,
14019 <parameter>token</parameter> <type>text</type> )
14020 </para>
14021 <para>
14022 Extracts tokens from the <parameter>document</parameter> using the
14023 named parser.
14024 See <xref linkend="textsearch-parser-testing"/> for details.
14025 </para>
14026 <para>
14027 <literal>ts_parse('default', 'foo - bar')</literal>
14028 <returnvalue>(1,foo) ...</returnvalue>
14029 </para></entry>
14030 </row>
14032 <row>
14033 <entry role="func_table_entry"><para role="func_signature">
14034 <function>ts_parse</function> ( <parameter>parser_oid</parameter> <type>oid</type>,
14035 <parameter>document</parameter> <type>text</type> )
14036 <returnvalue>setof record</returnvalue>
14037 ( <parameter>tokid</parameter> <type>integer</type>,
14038 <parameter>token</parameter> <type>text</type> )
14039 </para>
14040 <para>
14041 Extracts tokens from the <parameter>document</parameter> using a
14042 parser specified by OID.
14043 See <xref linkend="textsearch-parser-testing"/> for details.
14044 </para>
14045 <para>
14046 <literal>ts_parse(3722, 'foo - bar')</literal>
14047 <returnvalue>(1,foo) ...</returnvalue>
14048 </para></entry>
14049 </row>
14051 <row>
14052 <entry role="func_table_entry"><para role="func_signature">
14053 <indexterm>
14054 <primary>ts_token_type</primary>
14055 </indexterm>
14056 <function>ts_token_type</function> ( <parameter>parser_name</parameter> <type>text</type> )
14057 <returnvalue>setof record</returnvalue>
14058 ( <parameter>tokid</parameter> <type>integer</type>,
14059 <parameter>alias</parameter> <type>text</type>,
14060 <parameter>description</parameter> <type>text</type> )
14061 </para>
14062 <para>
14063 Returns a table that describes each type of token the named parser can
14064 recognize.
14065 See <xref linkend="textsearch-parser-testing"/> for details.
14066 </para>
14067 <para>
14068 <literal>ts_token_type('default')</literal>
14069 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
14070 </para></entry>
14071 </row>
14073 <row>
14074 <entry role="func_table_entry"><para role="func_signature">
14075 <function>ts_token_type</function> ( <parameter>parser_oid</parameter> <type>oid</type> )
14076 <returnvalue>setof record</returnvalue>
14077 ( <parameter>tokid</parameter> <type>integer</type>,
14078 <parameter>alias</parameter> <type>text</type>,
14079 <parameter>description</parameter> <type>text</type> )
14080 </para>
14081 <para>
14082 Returns a table that describes each type of token a parser specified
14083 by OID can recognize.
14084 See <xref linkend="textsearch-parser-testing"/> for details.
14085 </para>
14086 <para>
14087 <literal>ts_token_type(3722)</literal>
14088 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
14089 </para></entry>
14090 </row>
14092 <row>
14093 <entry role="func_table_entry"><para role="func_signature">
14094 <indexterm>
14095 <primary>ts_stat</primary>
14096 </indexterm>
14097 <function>ts_stat</function> ( <parameter>sqlquery</parameter> <type>text</type>
14098 <optional>, <parameter>weights</parameter> <type>text</type> </optional> )
14099 <returnvalue>setof record</returnvalue>
14100 ( <parameter>word</parameter> <type>text</type>,
14101 <parameter>ndoc</parameter> <type>integer</type>,
14102 <parameter>nentry</parameter> <type>integer</type> )
14103 </para>
14104 <para>
14105 Executes the <parameter>sqlquery</parameter>, which must return a
14106 single <type>tsvector</type> column, and returns statistics about each
14107 distinct lexeme contained in the data.
14108 See <xref linkend="textsearch-statistics"/> for details.
14109 </para>
14110 <para>
14111 <literal>ts_stat('SELECT vector FROM apod')</literal>
14112 <returnvalue>(foo,10,15) ...</returnvalue>
14113 </para></entry>
14114 </row>
14115 </tbody>
14116 </tgroup>
14117 </table>
14119 </sect1>
14121 <sect1 id="functions-uuid">
14122 <title>UUID Functions</title>
14124 <indexterm zone="datatype-uuid">
14125 <primary>UUID</primary>
14126 <secondary>generating</secondary>
14127 </indexterm>
14129 <indexterm>
14130 <primary>gen_random_uuid</primary>
14131 </indexterm>
14133 <para>
14134 <productname>PostgreSQL</productname> includes one function to generate a UUID:
14135 <synopsis>
14136 <function>gen_random_uuid</function> () <returnvalue>uuid</returnvalue>
14137 </synopsis>
14138 This function returns a version 4 (random) UUID. This is the most commonly
14139 used type of UUID and is appropriate for most applications.
14140 </para>
14142 <para>
14143 The <xref linkend="uuid-ossp"/> module provides additional functions that
14144 implement other standard algorithms for generating UUIDs.
14145 </para>
14147 <para>
14148 <productname>PostgreSQL</productname> also provides the usual comparison
14149 operators shown in <xref linkend="functions-comparison-op-table"/> for
14150 UUIDs.
14151 </para>
14152 </sect1>
14154 <sect1 id="functions-xml">
14156 <title>XML Functions</title>
14158 <indexterm>
14159 <primary>XML Functions</primary>
14160 </indexterm>
14162 <para>
14163 The functions and function-like expressions described in this
14164 section operate on values of type <type>xml</type>. See <xref
14165 linkend="datatype-xml"/> for information about the <type>xml</type>
14166 type. The function-like expressions <function>xmlparse</function>
14167 and <function>xmlserialize</function> for converting to and from
14168 type <type>xml</type> are documented there, not in this section.
14169 </para>
14171 <para>
14172 Use of most of these functions
14173 requires <productname>PostgreSQL</productname> to have been built
14174 with <command>configure --with-libxml</command>.
14175 </para>
14177 <sect2 id="functions-producing-xml">
14178 <title>Producing XML Content</title>
14180 <para>
14181 A set of functions and function-like expressions is available for
14182 producing XML content from SQL data. As such, they are
14183 particularly suitable for formatting query results into XML
14184 documents for processing in client applications.
14185 </para>
14187 <sect3 id="functions-producing-xml-xmltext">
14188 <title><literal>xmltext</literal></title>
14190 <indexterm>
14191 <primary>xmltext</primary>
14192 </indexterm>
14194 <synopsis>
14195 <function>xmltext</function> ( <type>text</type> ) <returnvalue>xml</returnvalue>
14196 </synopsis>
14198 <para>
14199 The function <function>xmltext</function> returns an XML value with a single
14200 text node containing the input argument as its content. Predefined entities
14201 like ampersand (<literal><![CDATA[&]]></literal>), left and right angle brackets
14202 (<literal><![CDATA[< >]]></literal>), and quotation marks (<literal><![CDATA[""]]></literal>)
14203 are escaped.
14204 </para>
14206 <para>
14207 Example:
14208 <screen><![CDATA[
14209 SELECT xmltext('< foo & bar >');
14210 xmltext
14211 -------------------------
14212 &lt; foo &amp; bar &gt;
14213 ]]></screen>
14214 </para>
14215 </sect3>
14217 <sect3 id="functions-producing-xml-xmlcomment">
14218 <title><literal>xmlcomment</literal></title>
14220 <indexterm>
14221 <primary>xmlcomment</primary>
14222 </indexterm>
14224 <synopsis>
14225 <function>xmlcomment</function> ( <type>text</type> ) <returnvalue>xml</returnvalue>
14226 </synopsis>
14228 <para>
14229 The function <function>xmlcomment</function> creates an XML value
14230 containing an XML comment with the specified text as content.
14231 The text cannot contain <quote><literal>--</literal></quote> or end with a
14232 <quote><literal>-</literal></quote>, otherwise the resulting construct
14233 would not be a valid XML comment.
14234 If the argument is null, the result is null.
14235 </para>
14237 <para>
14238 Example:
14239 <screen><![CDATA[
14240 SELECT xmlcomment('hello');
14242 xmlcomment
14243 --------------
14244 <!--hello-->
14245 ]]></screen>
14246 </para>
14247 </sect3>
14249 <sect3 id="functions-producing-xml-xmlconcat">
14250 <title><literal>xmlconcat</literal></title>
14252 <indexterm>
14253 <primary>xmlconcat</primary>
14254 </indexterm>
14256 <synopsis>
14257 <function>xmlconcat</function> ( <type>xml</type> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
14258 </synopsis>
14260 <para>
14261 The function <function>xmlconcat</function> concatenates a list
14262 of individual XML values to create a single value containing an
14263 XML content fragment. Null values are omitted; the result is
14264 only null if there are no nonnull arguments.
14265 </para>
14267 <para>
14268 Example:
14269 <screen><![CDATA[
14270 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
14272 xmlconcat
14273 ----------------------
14274 <abc/><bar>foo</bar>
14275 ]]></screen>
14276 </para>
14278 <para>
14279 XML declarations, if present, are combined as follows. If all
14280 argument values have the same XML version declaration, that
14281 version is used in the result, else no version is used. If all
14282 argument values have the standalone declaration value
14283 <quote>yes</quote>, then that value is used in the result. If
14284 all argument values have a standalone declaration value and at
14285 least one is <quote>no</quote>, then that is used in the result.
14286 Else the result will have no standalone declaration. If the
14287 result is determined to require a standalone declaration but no
14288 version declaration, a version declaration with version 1.0 will
14289 be used because XML requires an XML declaration to contain a
14290 version declaration. Encoding declarations are ignored and
14291 removed in all cases.
14292 </para>
14294 <para>
14295 Example:
14296 <screen><![CDATA[
14297 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
14299 xmlconcat
14300 -----------------------------------
14301 <?xml version="1.1"?><foo/><bar/>
14302 ]]></screen>
14303 </para>
14304 </sect3>
14306 <sect3 id="functions-producing-xml-xmlelement">
14307 <title><literal>xmlelement</literal></title>
14309 <indexterm>
14310 <primary>xmlelement</primary>
14311 </indexterm>
14313 <synopsis>
14314 <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>
14315 </synopsis>
14317 <para>
14318 The <function>xmlelement</function> expression produces an XML
14319 element with the given name, attributes, and content.
14320 The <replaceable>name</replaceable>
14321 and <replaceable>attname</replaceable> items shown in the syntax are
14322 simple identifiers, not values. The <replaceable>attvalue</replaceable>
14323 and <replaceable>content</replaceable> items are expressions, which can
14324 yield any <productname>PostgreSQL</productname> data type. The
14325 argument(s) within <literal>XMLATTRIBUTES</literal> generate attributes
14326 of the XML element; the <replaceable>content</replaceable> value(s) are
14327 concatenated to form its content.
14328 </para>
14330 <para>
14331 Examples:
14332 <screen><![CDATA[
14333 SELECT xmlelement(name foo);
14335 xmlelement
14336 ------------
14337 <foo/>
14339 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
14341 xmlelement
14342 ------------------
14343 <foo bar="xyz"/>
14345 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
14347 xmlelement
14348 -------------------------------------
14349 <foo bar="2007-01-26">content</foo>
14350 ]]></screen>
14351 </para>
14353 <para>
14354 Element and attribute names that are not valid XML names are
14355 escaped by replacing the offending characters by the sequence
14356 <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
14357 <replaceable>HHHH</replaceable> is the character's Unicode
14358 codepoint in hexadecimal notation. For example:
14359 <screen><![CDATA[
14360 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
14362 xmlelement
14363 ----------------------------------
14364 <foo_x0024_bar a_x0026_b="xyz"/>
14365 ]]></screen>
14366 </para>
14368 <para>
14369 An explicit attribute name need not be specified if the attribute
14370 value is a column reference, in which case the column's name will
14371 be used as the attribute name by default. In other cases, the
14372 attribute must be given an explicit name. So this example is
14373 valid:
14374 <screen>
14375 CREATE TABLE test (a xml, b xml);
14376 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
14377 </screen>
14378 But these are not:
14379 <screen>
14380 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
14381 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
14382 </screen>
14383 </para>
14385 <para>
14386 Element content, if specified, will be formatted according to
14387 its data type. If the content is itself of type <type>xml</type>,
14388 complex XML documents can be constructed. For example:
14389 <screen><![CDATA[
14390 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
14391 xmlelement(name abc),
14392 xmlcomment('test'),
14393 xmlelement(name xyz));
14395 xmlelement
14396 ----------------------------------------------
14397 <foo bar="xyz"><abc/><!--test--><xyz/></foo>
14398 ]]></screen>
14400 Content of other types will be formatted into valid XML character
14401 data. This means in particular that the characters &lt;, &gt;,
14402 and &amp; will be converted to entities. Binary data (data type
14403 <type>bytea</type>) will be represented in base64 or hex
14404 encoding, depending on the setting of the configuration parameter
14405 <xref linkend="guc-xmlbinary"/>. The particular behavior for
14406 individual data types is expected to evolve in order to align the
14407 PostgreSQL mappings with those specified in SQL:2006 and later,
14408 as discussed in <xref linkend="functions-xml-limits-casts"/>.
14409 </para>
14410 </sect3>
14412 <sect3 id="functions-producing-xml-xmlforest">
14413 <title><literal>xmlforest</literal></title>
14415 <indexterm>
14416 <primary>xmlforest</primary>
14417 </indexterm>
14419 <synopsis>
14420 <function>xmlforest</function> ( <replaceable>content</replaceable> <optional> <literal>AS</literal> <replaceable>name</replaceable> </optional> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
14421 </synopsis>
14423 <para>
14424 The <function>xmlforest</function> expression produces an XML
14425 forest (sequence) of elements using the given names and content.
14426 As for <function>xmlelement</function>,
14427 each <replaceable>name</replaceable> must be a simple identifier, while
14428 the <replaceable>content</replaceable> expressions can have any data
14429 type.
14430 </para>
14432 <para>
14433 Examples:
14434 <screen>
14435 SELECT xmlforest('abc' AS foo, 123 AS bar);
14437 xmlforest
14438 ------------------------------
14439 &lt;foo&gt;abc&lt;/foo&gt;&lt;bar&gt;123&lt;/bar&gt;
14442 SELECT xmlforest(table_name, column_name)
14443 FROM information_schema.columns
14444 WHERE table_schema = 'pg_catalog';
14446 xmlforest
14447 ------------------------------------&zwsp;-----------------------------------
14448 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolname&lt;/column_name&gt;
14449 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolsuper&lt;/column_name&gt;
14451 </screen>
14453 As seen in the second example, the element name can be omitted if
14454 the content value is a column reference, in which case the column
14455 name is used by default. Otherwise, a name must be specified.
14456 </para>
14458 <para>
14459 Element names that are not valid XML names are escaped as shown
14460 for <function>xmlelement</function> above. Similarly, content
14461 data is escaped to make valid XML content, unless it is already
14462 of type <type>xml</type>.
14463 </para>
14465 <para>
14466 Note that XML forests are not valid XML documents if they consist
14467 of more than one element, so it might be useful to wrap
14468 <function>xmlforest</function> expressions in
14469 <function>xmlelement</function>.
14470 </para>
14471 </sect3>
14473 <sect3 id="functions-producing-xml-xmlpi">
14474 <title><literal>xmlpi</literal></title>
14476 <indexterm>
14477 <primary>xmlpi</primary>
14478 </indexterm>
14480 <synopsis>
14481 <function>xmlpi</function> ( <literal>NAME</literal> <replaceable>name</replaceable> <optional>, <replaceable>content</replaceable> </optional> ) <returnvalue>xml</returnvalue>
14482 </synopsis>
14484 <para>
14485 The <function>xmlpi</function> expression creates an XML
14486 processing instruction.
14487 As for <function>xmlelement</function>,
14488 the <replaceable>name</replaceable> must be a simple identifier, while
14489 the <replaceable>content</replaceable> expression can have any data type.
14490 The <replaceable>content</replaceable>, if present, must not contain the
14491 character sequence <literal>?&gt;</literal>.
14492 </para>
14494 <para>
14495 Example:
14496 <screen><![CDATA[
14497 SELECT xmlpi(name php, 'echo "hello world";');
14499 xmlpi
14500 -----------------------------
14501 <?php echo "hello world";?>
14502 ]]></screen>
14503 </para>
14504 </sect3>
14506 <sect3 id="functions-producing-xml-xmlroot">
14507 <title><literal>xmlroot</literal></title>
14509 <indexterm>
14510 <primary>xmlroot</primary>
14511 </indexterm>
14513 <synopsis>
14514 <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>
14515 </synopsis>
14517 <para>
14518 The <function>xmlroot</function> expression alters the properties
14519 of the root node of an XML value. If a version is specified,
14520 it replaces the value in the root node's version declaration; if a
14521 standalone setting is specified, it replaces the value in the
14522 root node's standalone declaration.
14523 </para>
14525 <para>
14526 <screen><![CDATA[
14527 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
14528 version '1.0', standalone yes);
14530 xmlroot
14531 ----------------------------------------
14532 <?xml version="1.0" standalone="yes"?>
14533 <content>abc</content>
14534 ]]></screen>
14535 </para>
14536 </sect3>
14538 <sect3 id="functions-xml-xmlagg">
14539 <title><literal>xmlagg</literal></title>
14541 <indexterm>
14542 <primary>xmlagg</primary>
14543 </indexterm>
14545 <synopsis>
14546 <function>xmlagg</function> ( <type>xml</type> ) <returnvalue>xml</returnvalue>
14547 </synopsis>
14549 <para>
14550 The function <function>xmlagg</function> is, unlike the other
14551 functions described here, an aggregate function. It concatenates the
14552 input values to the aggregate function call,
14553 much like <function>xmlconcat</function> does, except that concatenation
14554 occurs across rows rather than across expressions in a single row.
14555 See <xref linkend="functions-aggregate"/> for additional information
14556 about aggregate functions.
14557 </para>
14559 <para>
14560 Example:
14561 <screen><![CDATA[
14562 CREATE TABLE test (y int, x xml);
14563 INSERT INTO test VALUES (1, '<foo>abc</foo>');
14564 INSERT INTO test VALUES (2, '<bar/>');
14565 SELECT xmlagg(x) FROM test;
14566 xmlagg
14567 ----------------------
14568 <foo>abc</foo><bar/>
14569 ]]></screen>
14570 </para>
14572 <para>
14573 To determine the order of the concatenation, an <literal>ORDER BY</literal>
14574 clause may be added to the aggregate call as described in
14575 <xref linkend="syntax-aggregates"/>. For example:
14577 <screen><![CDATA[
14578 SELECT xmlagg(x ORDER BY y DESC) FROM test;
14579 xmlagg
14580 ----------------------
14581 <bar/><foo>abc</foo>
14582 ]]></screen>
14583 </para>
14585 <para>
14586 The following non-standard approach used to be recommended
14587 in previous versions, and may still be useful in specific
14588 cases:
14590 <screen><![CDATA[
14591 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
14592 xmlagg
14593 ----------------------
14594 <bar/><foo>abc</foo>
14595 ]]></screen>
14596 </para>
14597 </sect3>
14598 </sect2>
14600 <sect2 id="functions-xml-predicates">
14601 <title>XML Predicates</title>
14603 <para>
14604 The expressions described in this section check properties
14605 of <type>xml</type> values.
14606 </para>
14608 <sect3 id="functions-producing-xml-is-document">
14609 <title><literal>IS DOCUMENT</literal></title>
14611 <indexterm>
14612 <primary>IS DOCUMENT</primary>
14613 </indexterm>
14615 <synopsis>
14616 <type>xml</type> <literal>IS DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14617 </synopsis>
14619 <para>
14620 The expression <literal>IS DOCUMENT</literal> returns true if the
14621 argument XML value is a proper XML document, false if it is not
14622 (that is, it is a content fragment), or null if the argument is
14623 null. See <xref linkend="datatype-xml"/> about the difference
14624 between documents and content fragments.
14625 </para>
14626 </sect3>
14628 <sect3 id="functions-producing-xml-is-not-document">
14629 <title><literal>IS NOT DOCUMENT</literal></title>
14631 <indexterm>
14632 <primary>IS NOT DOCUMENT</primary>
14633 </indexterm>
14635 <synopsis>
14636 <type>xml</type> <literal>IS NOT DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14637 </synopsis>
14639 <para>
14640 The expression <literal>IS NOT DOCUMENT</literal> returns false if the
14641 argument XML value is a proper XML document, true if it is not (that is,
14642 it is a content fragment), or null if the argument is null.
14643 </para>
14644 </sect3>
14646 <sect3 id="xml-exists">
14647 <title><literal>XMLEXISTS</literal></title>
14649 <indexterm>
14650 <primary>XMLEXISTS</primary>
14651 </indexterm>
14653 <synopsis>
14654 <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>
14655 </synopsis>
14657 <para>
14658 The function <function>xmlexists</function> evaluates an XPath 1.0
14659 expression (the first argument), with the passed XML value as its context
14660 item. The function returns false if the result of that evaluation
14661 yields an empty node-set, true if it yields any other value. The
14662 function returns null if any argument is null. A nonnull value
14663 passed as the context item must be an XML document, not a content
14664 fragment or any non-XML value.
14665 </para>
14667 <para>
14668 Example:
14669 <screen><![CDATA[
14670 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '<towns><town>Toronto</town><town>Ottawa</town></towns>');
14672 xmlexists
14673 ------------
14675 (1 row)
14676 ]]></screen>
14677 </para>
14679 <para>
14680 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
14681 are accepted in <productname>PostgreSQL</productname>, but are ignored,
14682 as discussed in <xref linkend="functions-xml-limits-postgresql"/>.
14683 </para>
14685 <para>
14686 In the SQL standard, the <function>xmlexists</function> function
14687 evaluates an expression in the XML Query language,
14688 but <productname>PostgreSQL</productname> allows only an XPath 1.0
14689 expression, as discussed in
14690 <xref linkend="functions-xml-limits-xpath1"/>.
14691 </para>
14692 </sect3>
14694 <sect3 id="xml-is-well-formed">
14695 <title><literal>xml_is_well_formed</literal></title>
14697 <indexterm>
14698 <primary>xml_is_well_formed</primary>
14699 </indexterm>
14701 <indexterm>
14702 <primary>xml_is_well_formed_document</primary>
14703 </indexterm>
14705 <indexterm>
14706 <primary>xml_is_well_formed_content</primary>
14707 </indexterm>
14709 <synopsis>
14710 <function>xml_is_well_formed</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14711 <function>xml_is_well_formed_document</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14712 <function>xml_is_well_formed_content</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14713 </synopsis>
14715 <para>
14716 These functions check whether a <type>text</type> string represents
14717 well-formed XML, returning a Boolean result.
14718 <function>xml_is_well_formed_document</function> checks for a well-formed
14719 document, while <function>xml_is_well_formed_content</function> checks
14720 for well-formed content. <function>xml_is_well_formed</function> does
14721 the former if the <xref linkend="guc-xmloption"/> configuration
14722 parameter is set to <literal>DOCUMENT</literal>, or the latter if it is set to
14723 <literal>CONTENT</literal>. This means that
14724 <function>xml_is_well_formed</function> is useful for seeing whether
14725 a simple cast to type <type>xml</type> will succeed, whereas the other two
14726 functions are useful for seeing whether the corresponding variants of
14727 <function>XMLPARSE</function> will succeed.
14728 </para>
14730 <para>
14731 Examples:
14733 <screen><![CDATA[
14734 SET xmloption TO DOCUMENT;
14735 SELECT xml_is_well_formed('<>');
14736 xml_is_well_formed
14737 --------------------
14739 (1 row)
14741 SELECT xml_is_well_formed('<abc/>');
14742 xml_is_well_formed
14743 --------------------
14745 (1 row)
14747 SET xmloption TO CONTENT;
14748 SELECT xml_is_well_formed('abc');
14749 xml_is_well_formed
14750 --------------------
14752 (1 row)
14754 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
14755 xml_is_well_formed_document
14756 -----------------------------
14758 (1 row)
14760 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
14761 xml_is_well_formed_document
14762 -----------------------------
14764 (1 row)
14765 ]]></screen>
14767 The last example shows that the checks include whether
14768 namespaces are correctly matched.
14769 </para>
14770 </sect3>
14771 </sect2>
14773 <sect2 id="functions-xml-processing">
14774 <title>Processing XML</title>
14776 <para>
14777 To process values of data type <type>xml</type>, PostgreSQL offers
14778 the functions <function>xpath</function> and
14779 <function>xpath_exists</function>, which evaluate XPath 1.0
14780 expressions, and the <function>XMLTABLE</function>
14781 table function.
14782 </para>
14784 <sect3 id="functions-xml-processing-xpath">
14785 <title><literal>xpath</literal></title>
14787 <indexterm>
14788 <primary>XPath</primary>
14789 </indexterm>
14791 <synopsis>
14792 <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>
14793 </synopsis>
14795 <para>
14796 The function <function>xpath</function> evaluates the XPath 1.0
14797 expression <parameter>xpath</parameter> (given as text)
14798 against the XML value
14799 <parameter>xml</parameter>. It returns an array of XML values
14800 corresponding to the node-set produced by the XPath expression.
14801 If the XPath expression returns a scalar value rather than a node-set,
14802 a single-element array is returned.
14803 </para>
14805 <para>
14806 The second argument must be a well formed XML document. In particular,
14807 it must have a single root node element.
14808 </para>
14810 <para>
14811 The optional third argument of the function is an array of namespace
14812 mappings. This array should be a two-dimensional <type>text</type> array with
14813 the length of the second axis being equal to 2 (i.e., it should be an
14814 array of arrays, each of which consists of exactly 2 elements).
14815 The first element of each array entry is the namespace name (alias), the
14816 second the namespace URI. It is not required that aliases provided in
14817 this array be the same as those being used in the XML document itself (in
14818 other words, both in the XML document and in the <function>xpath</function>
14819 function context, aliases are <emphasis>local</emphasis>).
14820 </para>
14822 <para>
14823 Example:
14824 <screen><![CDATA[
14825 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
14826 ARRAY[ARRAY['my', 'http://example.com']]);
14828 xpath
14829 --------
14830 {test}
14831 (1 row)
14832 ]]></screen>
14833 </para>
14835 <para>
14836 To deal with default (anonymous) namespaces, do something like this:
14837 <screen><![CDATA[
14838 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
14839 ARRAY[ARRAY['mydefns', 'http://example.com']]);
14841 xpath
14842 --------
14843 {test}
14844 (1 row)
14845 ]]></screen>
14846 </para>
14847 </sect3>
14849 <sect3 id="functions-xml-processing-xpath-exists">
14850 <title><literal>xpath_exists</literal></title>
14852 <indexterm>
14853 <primary>xpath_exists</primary>
14854 </indexterm>
14856 <synopsis>
14857 <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>
14858 </synopsis>
14860 <para>
14861 The function <function>xpath_exists</function> is a specialized form
14862 of the <function>xpath</function> function. Instead of returning the
14863 individual XML values that satisfy the XPath 1.0 expression, this function
14864 returns a Boolean indicating whether the query was satisfied or not
14865 (specifically, whether it produced any value other than an empty node-set).
14866 This function is equivalent to the <literal>XMLEXISTS</literal> predicate,
14867 except that it also offers support for a namespace mapping argument.
14868 </para>
14870 <para>
14871 Example:
14872 <screen><![CDATA[
14873 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
14874 ARRAY[ARRAY['my', 'http://example.com']]);
14876 xpath_exists
14877 --------------
14879 (1 row)
14880 ]]></screen>
14881 </para>
14882 </sect3>
14884 <sect3 id="functions-xml-processing-xmltable">
14885 <title><literal>xmltable</literal></title>
14887 <indexterm>
14888 <primary>xmltable</primary>
14889 </indexterm>
14891 <indexterm zone="functions-xml-processing-xmltable">
14892 <primary>table function</primary>
14893 <secondary>XMLTABLE</secondary>
14894 </indexterm>
14896 <synopsis>
14897 <function>XMLTABLE</function> (
14898 <optional> <literal>XMLNAMESPACES</literal> ( <replaceable>namespace_uri</replaceable> <literal>AS</literal> <replaceable>namespace_name</replaceable> <optional>, ...</optional> ), </optional>
14899 <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>
14900 <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>
14901 | <literal>FOR ORDINALITY</literal> }
14902 <optional>, ...</optional>
14903 ) <returnvalue>setof record</returnvalue>
14904 </synopsis>
14906 <para>
14907 The <function>xmltable</function> expression produces a table based
14908 on an XML value, an XPath filter to extract rows, and a
14909 set of column definitions.
14910 Although it syntactically resembles a function, it can only appear
14911 as a table in a query's <literal>FROM</literal> clause.
14912 </para>
14914 <para>
14915 The optional <literal>XMLNAMESPACES</literal> clause gives a
14916 comma-separated list of namespace definitions, where
14917 each <replaceable>namespace_uri</replaceable> is a <type>text</type>
14918 expression and each <replaceable>namespace_name</replaceable> is a simple
14919 identifier. It specifies the XML namespaces used in the document and
14920 their aliases. A default namespace specification is not currently
14921 supported.
14922 </para>
14924 <para>
14925 The required <replaceable>row_expression</replaceable> argument is an
14926 XPath 1.0 expression (given as <type>text</type>) that is evaluated,
14927 passing the XML value <replaceable>document_expression</replaceable> as
14928 its context item, to obtain a set of XML nodes. These nodes are what
14929 <function>xmltable</function> transforms into output rows. No rows
14930 will be produced if the <replaceable>document_expression</replaceable>
14931 is null, nor if the <replaceable>row_expression</replaceable> produces
14932 an empty node-set or any value other than a node-set.
14933 </para>
14935 <para>
14936 <replaceable>document_expression</replaceable> provides the context
14937 item for the <replaceable>row_expression</replaceable>. It must be a
14938 well-formed XML document; fragments/forests are not accepted.
14939 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
14940 are accepted but ignored, as discussed in
14941 <xref linkend="functions-xml-limits-postgresql"/>.
14942 </para>
14944 <para>
14945 In the SQL standard, the <function>xmltable</function> function
14946 evaluates expressions in the XML Query language,
14947 but <productname>PostgreSQL</productname> allows only XPath 1.0
14948 expressions, as discussed in
14949 <xref linkend="functions-xml-limits-xpath1"/>.
14950 </para>
14952 <para>
14953 The required <literal>COLUMNS</literal> clause specifies the
14954 column(s) that will be produced in the output table.
14955 See the syntax summary above for the format.
14956 A name is required for each column, as is a data type
14957 (unless <literal>FOR ORDINALITY</literal> is specified, in which case
14958 type <type>integer</type> is implicit). The path, default and
14959 nullability clauses are optional.
14960 </para>
14962 <para>
14963 A column marked <literal>FOR ORDINALITY</literal> will be populated
14964 with row numbers, starting with 1, in the order of nodes retrieved from
14965 the <replaceable>row_expression</replaceable>'s result node-set.
14966 At most one column may be marked <literal>FOR ORDINALITY</literal>.
14967 </para>
14969 <note>
14970 <para>
14971 XPath 1.0 does not specify an order for nodes in a node-set, so code
14972 that relies on a particular order of the results will be
14973 implementation-dependent. Details can be found in
14974 <xref linkend="xml-xpath-1-specifics"/>.
14975 </para>
14976 </note>
14978 <para>
14979 The <replaceable>column_expression</replaceable> for a column is an
14980 XPath 1.0 expression that is evaluated for each row, with the current
14981 node from the <replaceable>row_expression</replaceable> result as its
14982 context item, to find the value of the column. If
14983 no <replaceable>column_expression</replaceable> is given, then the
14984 column name is used as an implicit path.
14985 </para>
14987 <para>
14988 If a column's XPath expression returns a non-XML value (which is limited
14989 to string, boolean, or double in XPath 1.0) and the column has a
14990 PostgreSQL type other than <type>xml</type>, the column will be set
14991 as if by assigning the value's string representation to the PostgreSQL
14992 type. (If the value is a boolean, its string representation is taken
14993 to be <literal>1</literal> or <literal>0</literal> if the output
14994 column's type category is numeric, otherwise <literal>true</literal> or
14995 <literal>false</literal>.)
14996 </para>
14998 <para>
14999 If a column's XPath expression returns a non-empty set of XML nodes
15000 and the column's PostgreSQL type is <type>xml</type>, the column will
15001 be assigned the expression result exactly, if it is of document or
15002 content form.
15003 <footnote>
15004 <para>
15005 A result containing more than one element node at the top level, or
15006 non-whitespace text outside of an element, is an example of content form.
15007 An XPath result can be of neither form, for example if it returns an
15008 attribute node selected from the element that contains it. Such a result
15009 will be put into content form with each such disallowed node replaced by
15010 its string value, as defined for the XPath 1.0
15011 <function>string</function> function.
15012 </para>
15013 </footnote>
15014 </para>
15016 <para>
15017 A non-XML result assigned to an <type>xml</type> output column produces
15018 content, a single text node with the string value of the result.
15019 An XML result assigned to a column of any other type may not have more than
15020 one node, or an error is raised. If there is exactly one node, the column
15021 will be set as if by assigning the node's string
15022 value (as defined for the XPath 1.0 <function>string</function> function)
15023 to the PostgreSQL type.
15024 </para>
15026 <para>
15027 The string value of an XML element is the concatenation, in document order,
15028 of all text nodes contained in that element and its descendants. The string
15029 value of an element with no descendant text nodes is an
15030 empty string (not <literal>NULL</literal>).
15031 Any <literal>xsi:nil</literal> attributes are ignored.
15032 Note that the whitespace-only <literal>text()</literal> node between two non-text
15033 elements is preserved, and that leading whitespace on a <literal>text()</literal>
15034 node is not flattened.
15035 The XPath 1.0 <function>string</function> function may be consulted for the
15036 rules defining the string value of other XML node types and non-XML values.
15037 </para>
15039 <para>
15040 The conversion rules presented here are not exactly those of the SQL
15041 standard, as discussed in <xref linkend="functions-xml-limits-casts"/>.
15042 </para>
15044 <para>
15045 If the path expression returns an empty node-set
15046 (typically, when it does not match)
15047 for a given row, the column will be set to <literal>NULL</literal>, unless
15048 a <replaceable>default_expression</replaceable> is specified; then the
15049 value resulting from evaluating that expression is used.
15050 </para>
15052 <para>
15053 A <replaceable>default_expression</replaceable>, rather than being
15054 evaluated immediately when <function>xmltable</function> is called,
15055 is evaluated each time a default is needed for the column.
15056 If the expression qualifies as stable or immutable, the repeat
15057 evaluation may be skipped.
15058 This means that you can usefully use volatile functions like
15059 <function>nextval</function> in
15060 <replaceable>default_expression</replaceable>.
15061 </para>
15063 <para>
15064 Columns may be marked <literal>NOT NULL</literal>. If the
15065 <replaceable>column_expression</replaceable> for a <literal>NOT
15066 NULL</literal> column does not match anything and there is
15067 no <literal>DEFAULT</literal> or
15068 the <replaceable>default_expression</replaceable> also evaluates to null,
15069 an error is reported.
15070 </para>
15072 <para>
15073 Examples:
15074 <screen><![CDATA[
15075 CREATE TABLE xmldata AS SELECT
15076 xml $$
15077 <ROWS>
15078 <ROW id="1">
15079 <COUNTRY_ID>AU</COUNTRY_ID>
15080 <COUNTRY_NAME>Australia</COUNTRY_NAME>
15081 </ROW>
15082 <ROW id="5">
15083 <COUNTRY_ID>JP</COUNTRY_ID>
15084 <COUNTRY_NAME>Japan</COUNTRY_NAME>
15085 <PREMIER_NAME>Shinzo Abe</PREMIER_NAME>
15086 <SIZE unit="sq_mi">145935</SIZE>
15087 </ROW>
15088 <ROW id="6">
15089 <COUNTRY_ID>SG</COUNTRY_ID>
15090 <COUNTRY_NAME>Singapore</COUNTRY_NAME>
15091 <SIZE unit="sq_km">697</SIZE>
15092 </ROW>
15093 </ROWS>
15094 $$ AS data;
15096 SELECT xmltable.*
15097 FROM xmldata,
15098 XMLTABLE('//ROWS/ROW'
15099 PASSING data
15100 COLUMNS id int PATH '@id',
15101 ordinality FOR ORDINALITY,
15102 "COUNTRY_NAME" text,
15103 country_id text PATH 'COUNTRY_ID',
15104 size_sq_km float PATH 'SIZE[@unit = "sq_km"]',
15105 size_other text PATH
15106 'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)',
15107 premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified');
15109 id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
15110 ----+------------+--------------+------------+------------+--------------+---------------
15111 1 | 1 | Australia | AU | | | not specified
15112 5 | 2 | Japan | JP | | 145935 sq_mi | Shinzo Abe
15113 6 | 3 | Singapore | SG | 697 | | not specified
15114 ]]></screen>
15116 The following example shows concatenation of multiple text() nodes,
15117 usage of the column name as XPath filter, and the treatment of whitespace,
15118 XML comments and processing instructions:
15120 <screen><![CDATA[
15121 CREATE TABLE xmlelements AS SELECT
15122 xml $$
15123 <root>
15124 <element> Hello<!-- xyxxz -->2a2<?aaaaa?> <!--x--> bbb<x>xxx</x>CC </element>
15125 </root>
15126 $$ AS data;
15128 SELECT xmltable.*
15129 FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
15130 element
15131 -------------------------
15132 Hello2a2 bbbxxxCC
15133 ]]></screen>
15134 </para>
15136 <para>
15137 The following example illustrates how
15138 the <literal>XMLNAMESPACES</literal> clause can be used to specify
15139 a list of namespaces
15140 used in the XML document as well as in the XPath expressions:
15142 <screen><![CDATA[
15143 WITH xmldata(data) AS (VALUES ('
15144 <example xmlns="http://example.com/myns" xmlns:B="http://example.com/b">
15145 <item foo="1" B:bar="2"/>
15146 <item foo="3" B:bar="4"/>
15147 <item foo="4" B:bar="5"/>
15148 </example>'::xml)
15150 SELECT xmltable.*
15151 FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
15152 'http://example.com/b' AS "B"),
15153 '/x:example/x:item'
15154 PASSING (SELECT data FROM xmldata)
15155 COLUMNS foo int PATH '@foo',
15156 bar int PATH '@B:bar');
15157 foo | bar
15158 -----+-----
15159 1 | 2
15160 3 | 4
15161 4 | 5
15162 (3 rows)
15163 ]]></screen>
15164 </para>
15165 </sect3>
15166 </sect2>
15168 <sect2 id="functions-xml-mapping">
15169 <title>Mapping Tables to XML</title>
15171 <indexterm zone="functions-xml-mapping">
15172 <primary>XML export</primary>
15173 </indexterm>
15175 <para>
15176 The following functions map the contents of relational tables to
15177 XML values. They can be thought of as XML export functionality:
15178 <synopsis>
15179 <function>table_to_xml</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15180 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15181 <function>query_to_xml</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15182 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15183 <function>cursor_to_xml</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>count</parameter> <type>integer</type>, <parameter>nulls</parameter> <type>boolean</type>,
15184 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15185 </synopsis>
15186 </para>
15188 <para>
15189 <function>table_to_xml</function> maps the content of the named
15190 table, passed as parameter <parameter>table</parameter>. The
15191 <type>regclass</type> type accepts strings identifying tables using the
15192 usual notation, including optional schema qualification and
15193 double quotes (see <xref linkend="datatype-oid"/> for details).
15194 <function>query_to_xml</function> executes the
15195 query whose text is passed as parameter
15196 <parameter>query</parameter> and maps the result set.
15197 <function>cursor_to_xml</function> fetches the indicated number of
15198 rows from the cursor specified by the parameter
15199 <parameter>cursor</parameter>. This variant is recommended if
15200 large tables have to be mapped, because the result value is built
15201 up in memory by each function.
15202 </para>
15204 <para>
15205 If <parameter>tableforest</parameter> is false, then the resulting
15206 XML document looks like this:
15207 <screen><![CDATA[
15208 <tablename>
15209 <row>
15210 <columnname1>data</columnname1>
15211 <columnname2>data</columnname2>
15212 </row>
15214 <row>
15216 </row>
15219 </tablename>
15220 ]]></screen>
15222 If <parameter>tableforest</parameter> is true, the result is an
15223 XML content fragment that looks like this:
15224 <screen><![CDATA[
15225 <tablename>
15226 <columnname1>data</columnname1>
15227 <columnname2>data</columnname2>
15228 </tablename>
15230 <tablename>
15232 </tablename>
15235 ]]></screen>
15237 If no table name is available, that is, when mapping a query or a
15238 cursor, the string <literal>table</literal> is used in the first
15239 format, <literal>row</literal> in the second format.
15240 </para>
15242 <para>
15243 The choice between these formats is up to the user. The first
15244 format is a proper XML document, which will be important in many
15245 applications. The second format tends to be more useful in the
15246 <function>cursor_to_xml</function> function if the result values are to be
15247 reassembled into one document later on. The functions for
15248 producing XML content discussed above, in particular
15249 <function>xmlelement</function>, can be used to alter the results
15250 to taste.
15251 </para>
15253 <para>
15254 The data values are mapped in the same way as described for the
15255 function <function>xmlelement</function> above.
15256 </para>
15258 <para>
15259 The parameter <parameter>nulls</parameter> determines whether null
15260 values should be included in the output. If true, null values in
15261 columns are represented as:
15262 <screen><![CDATA[
15263 <columnname xsi:nil="true"/>
15264 ]]></screen>
15265 where <literal>xsi</literal> is the XML namespace prefix for XML
15266 Schema Instance. An appropriate namespace declaration will be
15267 added to the result value. If false, columns containing null
15268 values are simply omitted from the output.
15269 </para>
15271 <para>
15272 The parameter <parameter>targetns</parameter> specifies the
15273 desired XML namespace of the result. If no particular namespace
15274 is wanted, an empty string should be passed.
15275 </para>
15277 <para>
15278 The following functions return XML Schema documents describing the
15279 mappings performed by the corresponding functions above:
15280 <synopsis>
15281 <function>table_to_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15282 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15283 <function>query_to_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15284 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15285 <function>cursor_to_xmlschema</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>nulls</parameter> <type>boolean</type>,
15286 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15287 </synopsis>
15288 It is essential that the same parameters are passed in order to
15289 obtain matching XML data mappings and XML Schema documents.
15290 </para>
15292 <para>
15293 The following functions produce XML data mappings and the
15294 corresponding XML Schema in one document (or forest), linked
15295 together. They can be useful where self-contained and
15296 self-describing results are wanted:
15297 <synopsis>
15298 <function>table_to_xml_and_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15299 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15300 <function>query_to_xml_and_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15301 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15302 </synopsis>
15303 </para>
15305 <para>
15306 In addition, the following functions are available to produce
15307 analogous mappings of entire schemas or the entire current
15308 database:
15309 <synopsis>
15310 <function>schema_to_xml</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15311 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15312 <function>schema_to_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15313 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15314 <function>schema_to_xml_and_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15315 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15317 <function>database_to_xml</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15318 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15319 <function>database_to_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15320 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15321 <function>database_to_xml_and_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15322 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15323 </synopsis>
15325 These functions ignore tables that are not readable by the current user.
15326 The database-wide functions additionally ignore schemas that the current
15327 user does not have <literal>USAGE</literal> (lookup) privilege for.
15328 </para>
15330 <para>
15331 Note that these potentially produce a lot of data, which needs to
15332 be built up in memory. When requesting content mappings of large
15333 schemas or databases, it might be worthwhile to consider mapping the
15334 tables separately instead, possibly even through a cursor.
15335 </para>
15337 <para>
15338 The result of a schema content mapping looks like this:
15340 <screen><![CDATA[
15341 <schemaname>
15343 table1-mapping
15345 table2-mapping
15349 </schemaname>]]></screen>
15351 where the format of a table mapping depends on the
15352 <parameter>tableforest</parameter> parameter as explained above.
15353 </para>
15355 <para>
15356 The result of a database content mapping looks like this:
15358 <screen><![CDATA[
15359 <dbname>
15361 <schema1name>
15363 </schema1name>
15365 <schema2name>
15367 </schema2name>
15371 </dbname>]]></screen>
15373 where the schema mapping is as above.
15374 </para>
15376 <para>
15377 As an example of using the output produced by these functions,
15378 <xref linkend="xslt-xml-html"/> shows an XSLT stylesheet that
15379 converts the output of
15380 <function>table_to_xml_and_xmlschema</function> to an HTML
15381 document containing a tabular rendition of the table data. In a
15382 similar manner, the results from these functions can be
15383 converted into other XML-based formats.
15384 </para>
15386 <example id="xslt-xml-html">
15387 <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
15388 <programlisting><![CDATA[
15389 <?xml version="1.0"?>
15390 <xsl:stylesheet version="1.0"
15391 xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
15392 xmlns:xsd="http://www.w3.org/2001/XMLSchema"
15393 xmlns="http://www.w3.org/1999/xhtml"
15396 <xsl:output method="xml"
15397 doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
15398 doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
15399 indent="yes"/>
15401 <xsl:template match="/*">
15402 <xsl:variable name="schema" select="//xsd:schema"/>
15403 <xsl:variable name="tabletypename"
15404 select="$schema/xsd:element[@name=name(current())]/@type"/>
15405 <xsl:variable name="rowtypename"
15406 select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
15408 <html>
15409 <head>
15410 <title><xsl:value-of select="name(current())"/></title>
15411 </head>
15412 <body>
15413 <table>
15414 <tr>
15415 <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
15416 <th><xsl:value-of select="."/></th>
15417 </xsl:for-each>
15418 </tr>
15420 <xsl:for-each select="row">
15421 <tr>
15422 <xsl:for-each select="*">
15423 <td><xsl:value-of select="."/></td>
15424 </xsl:for-each>
15425 </tr>
15426 </xsl:for-each>
15427 </table>
15428 </body>
15429 </html>
15430 </xsl:template>
15432 </xsl:stylesheet>
15433 ]]></programlisting>
15434 </example>
15435 </sect2>
15436 </sect1>
15438 <sect1 id="functions-json">
15439 <title>JSON Functions and Operators</title>
15441 <indexterm zone="functions-json">
15442 <primary>JSON</primary>
15443 <secondary>functions and operators</secondary>
15444 </indexterm>
15445 <indexterm zone="functions-json">
15446 <primary>SQL/JSON</primary>
15447 <secondary>functions and expressions</secondary>
15448 </indexterm>
15450 <para>
15451 This section describes:
15453 <itemizedlist>
15454 <listitem>
15455 <para>
15456 functions and operators for processing and creating JSON data
15457 </para>
15458 </listitem>
15459 <listitem>
15460 <para>
15461 the SQL/JSON path language
15462 </para>
15463 </listitem>
15464 </itemizedlist>
15465 </para>
15467 <para>
15468 To provide native support for JSON data types within the SQL environment,
15469 <productname>PostgreSQL</productname> implements the
15470 <firstterm>SQL/JSON data model</firstterm>.
15471 This model comprises sequences of items. Each item can hold SQL scalar
15472 values, with an additional SQL/JSON null value, and composite data structures
15473 that use JSON arrays and objects. The model is a formalization of the implied
15474 data model in the JSON specification
15475 <ulink url="https://tools.ietf.org/html/rfc7159">RFC 7159</ulink>.
15476 </para>
15478 <para>
15479 SQL/JSON allows you to handle JSON data alongside regular SQL data,
15480 with transaction support, including:
15482 <itemizedlist>
15483 <listitem>
15484 <para>
15485 Uploading JSON data into the database and storing it in
15486 regular SQL columns as character or binary strings.
15487 </para>
15488 </listitem>
15489 <listitem>
15490 <para>
15491 Generating JSON objects and arrays from relational data.
15492 </para>
15493 </listitem>
15494 <listitem>
15495 <para>
15496 Querying JSON data using SQL/JSON query functions and
15497 SQL/JSON path language expressions.
15498 </para>
15499 </listitem>
15500 </itemizedlist>
15501 </para>
15503 <para>
15504 To learn more about the SQL/JSON standard, see
15505 <xref linkend="sqltr-19075-6"/>. For details on JSON types
15506 supported in <productname>PostgreSQL</productname>,
15507 see <xref linkend="datatype-json"/>.
15508 </para>
15510 <sect2 id="functions-json-processing">
15511 <title>Processing and Creating JSON Data</title>
15513 <para>
15514 <xref linkend="functions-json-op-table"/> shows the operators that
15515 are available for use with JSON data types (see <xref
15516 linkend="datatype-json"/>).
15517 In addition, the usual comparison operators shown in <xref
15518 linkend="functions-comparison-op-table"/> are available for
15519 <type>jsonb</type>, though not for <type>json</type>. The comparison
15520 operators follow the ordering rules for B-tree operations outlined in
15521 <xref linkend="json-indexing"/>.
15522 See also <xref linkend="functions-aggregate"/> for the aggregate
15523 function <function>json_agg</function> which aggregates record
15524 values as JSON, the aggregate function
15525 <function>json_object_agg</function> which aggregates pairs of values
15526 into a JSON object, and their <type>jsonb</type> equivalents,
15527 <function>jsonb_agg</function> and <function>jsonb_object_agg</function>.
15528 </para>
15530 <table id="functions-json-op-table">
15531 <title><type>json</type> and <type>jsonb</type> Operators</title>
15532 <tgroup cols="1">
15533 <thead>
15534 <row>
15535 <entry role="func_table_entry"><para role="func_signature">
15536 Operator
15537 </para>
15538 <para>
15539 Description
15540 </para>
15541 <para>
15542 Example(s)
15543 </para></entry>
15544 </row>
15545 </thead>
15547 <tbody>
15548 <row>
15549 <entry role="func_table_entry"><para role="func_signature">
15550 <type>json</type> <literal>-&gt;</literal> <type>integer</type>
15551 <returnvalue>json</returnvalue>
15552 </para>
15553 <para role="func_signature">
15554 <type>jsonb</type> <literal>-&gt;</literal> <type>integer</type>
15555 <returnvalue>jsonb</returnvalue>
15556 </para>
15557 <para>
15558 Extracts <parameter>n</parameter>'th element of JSON array
15559 (array elements are indexed from zero, but negative integers count
15560 from the end).
15561 </para>
15562 <para>
15563 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; 2</literal>
15564 <returnvalue>{"c":"baz"}</returnvalue>
15565 </para>
15566 <para>
15567 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; -3</literal>
15568 <returnvalue>{"a":"foo"}</returnvalue>
15569 </para></entry>
15570 </row>
15572 <row>
15573 <entry role="func_table_entry"><para role="func_signature">
15574 <type>json</type> <literal>-&gt;</literal> <type>text</type>
15575 <returnvalue>json</returnvalue>
15576 </para>
15577 <para role="func_signature">
15578 <type>jsonb</type> <literal>-&gt;</literal> <type>text</type>
15579 <returnvalue>jsonb</returnvalue>
15580 </para>
15581 <para>
15582 Extracts JSON object field with the given key.
15583 </para>
15584 <para>
15585 <literal>'{"a": {"b":"foo"}}'::json -&gt; 'a'</literal>
15586 <returnvalue>{"b":"foo"}</returnvalue>
15587 </para></entry>
15588 </row>
15590 <row>
15591 <entry role="func_table_entry"><para role="func_signature">
15592 <type>json</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15593 <returnvalue>text</returnvalue>
15594 </para>
15595 <para role="func_signature">
15596 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15597 <returnvalue>text</returnvalue>
15598 </para>
15599 <para>
15600 Extracts <parameter>n</parameter>'th element of JSON array,
15601 as <type>text</type>.
15602 </para>
15603 <para>
15604 <literal>'[1,2,3]'::json -&gt;&gt; 2</literal>
15605 <returnvalue>3</returnvalue>
15606 </para></entry>
15607 </row>
15609 <row>
15610 <entry role="func_table_entry"><para role="func_signature">
15611 <type>json</type> <literal>-&gt;&gt;</literal> <type>text</type>
15612 <returnvalue>text</returnvalue>
15613 </para>
15614 <para role="func_signature">
15615 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>text</type>
15616 <returnvalue>text</returnvalue>
15617 </para>
15618 <para>
15619 Extracts JSON object field with the given key, as <type>text</type>.
15620 </para>
15621 <para>
15622 <literal>'{"a":1,"b":2}'::json -&gt;&gt; 'b'</literal>
15623 <returnvalue>2</returnvalue>
15624 </para></entry>
15625 </row>
15627 <row>
15628 <entry role="func_table_entry"><para role="func_signature">
15629 <type>json</type> <literal>#&gt;</literal> <type>text[]</type>
15630 <returnvalue>json</returnvalue>
15631 </para>
15632 <para role="func_signature">
15633 <type>jsonb</type> <literal>#&gt;</literal> <type>text[]</type>
15634 <returnvalue>jsonb</returnvalue>
15635 </para>
15636 <para>
15637 Extracts JSON sub-object at the specified path, where path elements
15638 can be either field keys or array indexes.
15639 </para>
15640 <para>
15641 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt; '{a,b,1}'</literal>
15642 <returnvalue>"bar"</returnvalue>
15643 </para></entry>
15644 </row>
15646 <row>
15647 <entry role="func_table_entry"><para role="func_signature">
15648 <type>json</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15649 <returnvalue>text</returnvalue>
15650 </para>
15651 <para role="func_signature">
15652 <type>jsonb</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15653 <returnvalue>text</returnvalue>
15654 </para>
15655 <para>
15656 Extracts JSON sub-object at the specified path as <type>text</type>.
15657 </para>
15658 <para>
15659 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt;&gt; '{a,b,1}'</literal>
15660 <returnvalue>bar</returnvalue>
15661 </para></entry>
15662 </row>
15663 </tbody>
15664 </tgroup>
15665 </table>
15667 <note>
15668 <para>
15669 The field/element/path extraction operators return NULL, rather than
15670 failing, if the JSON input does not have the right structure to match
15671 the request; for example if no such key or array element exists.
15672 </para>
15673 </note>
15675 <para>
15676 Some further operators exist only for <type>jsonb</type>, as shown
15677 in <xref linkend="functions-jsonb-op-table"/>.
15678 <xref linkend="json-indexing"/>
15679 describes how these operators can be used to effectively search indexed
15680 <type>jsonb</type> data.
15681 </para>
15683 <table id="functions-jsonb-op-table">
15684 <title>Additional <type>jsonb</type> Operators</title>
15685 <tgroup cols="1">
15686 <thead>
15687 <row>
15688 <entry role="func_table_entry"><para role="func_signature">
15689 Operator
15690 </para>
15691 <para>
15692 Description
15693 </para>
15694 <para>
15695 Example(s)
15696 </para></entry>
15697 </row>
15698 </thead>
15700 <tbody>
15701 <row>
15702 <entry role="func_table_entry"><para role="func_signature">
15703 <type>jsonb</type> <literal>@&gt;</literal> <type>jsonb</type>
15704 <returnvalue>boolean</returnvalue>
15705 </para>
15706 <para>
15707 Does the first JSON value contain the second?
15708 (See <xref linkend="json-containment"/> for details about containment.)
15709 </para>
15710 <para>
15711 <literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal>
15712 <returnvalue>t</returnvalue>
15713 </para></entry>
15714 </row>
15716 <row>
15717 <entry role="func_table_entry"><para role="func_signature">
15718 <type>jsonb</type> <literal>&lt;@</literal> <type>jsonb</type>
15719 <returnvalue>boolean</returnvalue>
15720 </para>
15721 <para>
15722 Is the first JSON value contained in the second?
15723 </para>
15724 <para>
15725 <literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal>
15726 <returnvalue>t</returnvalue>
15727 </para></entry>
15728 </row>
15730 <row>
15731 <entry role="func_table_entry"><para role="func_signature">
15732 <type>jsonb</type> <literal>?</literal> <type>text</type>
15733 <returnvalue>boolean</returnvalue>
15734 </para>
15735 <para>
15736 Does the text string exist as a top-level key or array element within
15737 the JSON value?
15738 </para>
15739 <para>
15740 <literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal>
15741 <returnvalue>t</returnvalue>
15742 </para>
15743 <para>
15744 <literal>'["a", "b", "c"]'::jsonb ? 'b'</literal>
15745 <returnvalue>t</returnvalue>
15746 </para></entry>
15747 </row>
15749 <row>
15750 <entry role="func_table_entry"><para role="func_signature">
15751 <type>jsonb</type> <literal>?|</literal> <type>text[]</type>
15752 <returnvalue>boolean</returnvalue>
15753 </para>
15754 <para>
15755 Do any of the strings in the text array exist as top-level keys or
15756 array elements?
15757 </para>
15758 <para>
15759 <literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'd']</literal>
15760 <returnvalue>t</returnvalue>
15761 </para></entry>
15762 </row>
15764 <row>
15765 <entry role="func_table_entry"><para role="func_signature">
15766 <type>jsonb</type> <literal>?&amp;</literal> <type>text[]</type>
15767 <returnvalue>boolean</returnvalue>
15768 </para>
15769 <para>
15770 Do all of the strings in the text array exist as top-level keys or
15771 array elements?
15772 </para>
15773 <para>
15774 <literal>'["a", "b", "c"]'::jsonb ?&amp; array['a', 'b']</literal>
15775 <returnvalue>t</returnvalue>
15776 </para></entry>
15777 </row>
15779 <row>
15780 <entry role="func_table_entry"><para role="func_signature">
15781 <type>jsonb</type> <literal>||</literal> <type>jsonb</type>
15782 <returnvalue>jsonb</returnvalue>
15783 </para>
15784 <para>
15785 Concatenates two <type>jsonb</type> values.
15786 Concatenating two arrays generates an array containing all the
15787 elements of each input. Concatenating two objects generates an
15788 object containing the union of their
15789 keys, taking the second object's value when there are duplicate keys.
15790 All other cases are treated by converting a non-array input into a
15791 single-element array, and then proceeding as for two arrays.
15792 Does not operate recursively: only the top-level array or object
15793 structure is merged.
15794 </para>
15795 <para>
15796 <literal>'["a", "b"]'::jsonb || '["a", "d"]'::jsonb</literal>
15797 <returnvalue>["a", "b", "a", "d"]</returnvalue>
15798 </para>
15799 <para>
15800 <literal>'{"a": "b"}'::jsonb || '{"c": "d"}'::jsonb</literal>
15801 <returnvalue>{"a": "b", "c": "d"}</returnvalue>
15802 </para>
15803 <para>
15804 <literal>'[1, 2]'::jsonb || '3'::jsonb</literal>
15805 <returnvalue>[1, 2, 3]</returnvalue>
15806 </para>
15807 <para>
15808 <literal>'{"a": "b"}'::jsonb || '42'::jsonb</literal>
15809 <returnvalue>[{"a": "b"}, 42]</returnvalue>
15810 </para>
15811 <para>
15812 To append an array to another array as a single entry, wrap it
15813 in an additional layer of array, for example:
15814 </para>
15815 <para>
15816 <literal>'[1, 2]'::jsonb || jsonb_build_array('[3, 4]'::jsonb)</literal>
15817 <returnvalue>[1, 2, [3, 4]]</returnvalue>
15818 </para></entry>
15819 </row>
15821 <row>
15822 <entry role="func_table_entry"><para role="func_signature">
15823 <type>jsonb</type> <literal>-</literal> <type>text</type>
15824 <returnvalue>jsonb</returnvalue>
15825 </para>
15826 <para>
15827 Deletes a key (and its value) from a JSON object, or matching string
15828 value(s) from a JSON array.
15829 </para>
15830 <para>
15831 <literal>'{"a": "b", "c": "d"}'::jsonb - 'a'</literal>
15832 <returnvalue>{"c": "d"}</returnvalue>
15833 </para>
15834 <para>
15835 <literal>'["a", "b", "c", "b"]'::jsonb - 'b'</literal>
15836 <returnvalue>["a", "c"]</returnvalue>
15837 </para></entry>
15838 </row>
15840 <row>
15841 <entry role="func_table_entry"><para role="func_signature">
15842 <type>jsonb</type> <literal>-</literal> <type>text[]</type>
15843 <returnvalue>jsonb</returnvalue>
15844 </para>
15845 <para>
15846 Deletes all matching keys or array elements from the left operand.
15847 </para>
15848 <para>
15849 <literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[]</literal>
15850 <returnvalue>{}</returnvalue>
15851 </para></entry>
15852 </row>
15854 <row>
15855 <entry role="func_table_entry"><para role="func_signature">
15856 <type>jsonb</type> <literal>-</literal> <type>integer</type>
15857 <returnvalue>jsonb</returnvalue>
15858 </para>
15859 <para>
15860 Deletes the array element with specified index (negative
15861 integers count from the end). Throws an error if JSON value
15862 is not an array.
15863 </para>
15864 <para>
15865 <literal>'["a", "b"]'::jsonb - 1 </literal>
15866 <returnvalue>["a"]</returnvalue>
15867 </para></entry>
15868 </row>
15870 <row>
15871 <entry role="func_table_entry"><para role="func_signature">
15872 <type>jsonb</type> <literal>#-</literal> <type>text[]</type>
15873 <returnvalue>jsonb</returnvalue>
15874 </para>
15875 <para>
15876 Deletes the field or array element at the specified path, where path
15877 elements can be either field keys or array indexes.
15878 </para>
15879 <para>
15880 <literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal>
15881 <returnvalue>["a", {}]</returnvalue>
15882 </para></entry>
15883 </row>
15885 <row>
15886 <entry role="func_table_entry"><para role="func_signature">
15887 <type>jsonb</type> <literal>@?</literal> <type>jsonpath</type>
15888 <returnvalue>boolean</returnvalue>
15889 </para>
15890 <para>
15891 Does JSON path return any item for the specified JSON value?
15892 </para>
15893 <para>
15894 <literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal>
15895 <returnvalue>t</returnvalue>
15896 </para></entry>
15897 </row>
15899 <row>
15900 <entry role="func_table_entry"><para role="func_signature">
15901 <type>jsonb</type> <literal>@@</literal> <type>jsonpath</type>
15902 <returnvalue>boolean</returnvalue>
15903 </para>
15904 <para>
15905 Returns the result of a JSON path predicate check for the
15906 specified JSON value. Only the first item of the result is taken into
15907 account. If the result is not Boolean, then <literal>NULL</literal>
15908 is returned.
15909 </para>
15910 <para>
15911 <literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal>
15912 <returnvalue>t</returnvalue>
15913 </para></entry>
15914 </row>
15915 </tbody>
15916 </tgroup>
15917 </table>
15919 <note>
15920 <para>
15921 The <type>jsonpath</type> operators <literal>@?</literal>
15922 and <literal>@@</literal> suppress the following errors: missing object
15923 field or array element, unexpected JSON item type, datetime and numeric
15924 errors. The <type>jsonpath</type>-related functions described below can
15925 also be told to suppress these types of errors. This behavior might be
15926 helpful when searching JSON document collections of varying structure.
15927 </para>
15928 </note>
15930 <para>
15931 <xref linkend="functions-json-creation-table"/> shows the functions that are
15932 available for constructing <type>json</type> and <type>jsonb</type> values.
15933 Some functions in this table have a <literal>RETURNING</literal> clause,
15934 which specifies the data type returned. It must be one of <type>json</type>,
15935 <type>jsonb</type>, <type>bytea</type>, a character string type (<type>text</type>,
15936 <type>char</type>, <type>varchar</type>, or <type>nchar</type>), or a type
15937 for which there is a cast from <type>json</type> to that type.
15938 By default, the <type>json</type> type is returned.
15939 </para>
15941 <table id="functions-json-creation-table">
15942 <title>JSON Creation Functions</title>
15943 <tgroup cols="1">
15944 <thead>
15945 <row>
15946 <entry role="func_table_entry"><para role="func_signature">
15947 Function
15948 </para>
15949 <para>
15950 Description
15951 </para>
15952 <para>
15953 Example(s)
15954 </para></entry>
15955 </row>
15956 </thead>
15958 <tbody>
15959 <row>
15960 <entry role="func_table_entry"><para role="func_signature">
15961 <indexterm>
15962 <primary>to_json</primary>
15963 </indexterm>
15964 <function>to_json</function> ( <type>anyelement</type> )
15965 <returnvalue>json</returnvalue>
15966 </para>
15967 <para role="func_signature">
15968 <indexterm>
15969 <primary>to_jsonb</primary>
15970 </indexterm>
15971 <function>to_jsonb</function> ( <type>anyelement</type> )
15972 <returnvalue>jsonb</returnvalue>
15973 </para>
15974 <para>
15975 Converts any SQL value to <type>json</type> or <type>jsonb</type>.
15976 Arrays and composites are converted recursively to arrays and
15977 objects (multidimensional arrays become arrays of arrays in JSON).
15978 Otherwise, if there is a cast from the SQL data type
15979 to <type>json</type>, the cast function will be used to perform the
15980 conversion;<footnote>
15981 <para>
15982 For example, the <xref linkend="hstore"/> extension has a cast
15983 from <type>hstore</type> to <type>json</type>, so that
15984 <type>hstore</type> values converted via the JSON creation functions
15985 will be represented as JSON objects, not as primitive string values.
15986 </para>
15987 </footnote>
15988 otherwise, a scalar JSON value is produced. For any scalar other than
15989 a number, a Boolean, or a null value, the text representation will be
15990 used, with escaping as necessary to make it a valid JSON string value.
15991 </para>
15992 <para>
15993 <literal>to_json('Fred said "Hi."'::text)</literal>
15994 <returnvalue>"Fred said \"Hi.\""</returnvalue>
15995 </para>
15996 <para>
15997 <literal>to_jsonb(row(42, 'Fred said "Hi."'::text))</literal>
15998 <returnvalue>{"f1": 42, "f2": "Fred said \"Hi.\""}</returnvalue>
15999 </para></entry>
16000 </row>
16002 <row>
16003 <entry role="func_table_entry"><para role="func_signature">
16004 <indexterm>
16005 <primary>array_to_json</primary>
16006 </indexterm>
16007 <function>array_to_json</function> ( <type>anyarray</type> <optional>, <type>boolean</type> </optional> )
16008 <returnvalue>json</returnvalue>
16009 </para>
16010 <para>
16011 Converts an SQL array to a JSON array. The behavior is the same
16012 as <function>to_json</function> except that line feeds will be added
16013 between top-level array elements if the optional boolean parameter is
16014 true.
16015 </para>
16016 <para>
16017 <literal>array_to_json('{{1,5},{99,100}}'::int[])</literal>
16018 <returnvalue>[[1,5],[99,100]]</returnvalue>
16019 </para></entry>
16020 </row>
16022 <row>
16023 <!--
16024 Note that this is barely legible in the output; it looks like a
16025 salad of braces and brackets. It would be better to split it out
16026 in multiple lines, but that's surprisingly hard to do in a way that
16027 matches in HTML and PDF output. Other standard SQL/JSON functions
16028 have the same problem.
16030 <entry role="func_table_entry"><para role="func_signature">
16031 <indexterm><primary>json_array</primary></indexterm>
16032 <function>json_array</function> (
16033 <optional> { <replaceable>value_expression</replaceable> <optional> <literal>FORMAT JSON</literal> </optional> } <optional>, ...</optional> </optional>
16034 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
16035 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
16036 </para>
16037 <para role="func_signature">
16038 <function>json_array</function> (
16039 <optional> <replaceable>query_expression</replaceable> </optional>
16040 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
16041 </para>
16042 <para>
16043 Constructs a JSON array from either a series of
16044 <replaceable>value_expression</replaceable> parameters or from the results
16045 of <replaceable>query_expression</replaceable>,
16046 which must be a SELECT query returning a single column. If
16047 <literal>ABSENT ON NULL</literal> is specified, NULL values are ignored.
16048 This is always the case if a
16049 <replaceable>query_expression</replaceable> is used.
16050 </para>
16051 <para>
16052 <literal>json_array(1,true,json '{"a":null}')</literal>
16053 <returnvalue>[1, true, {"a":null}]</returnvalue>
16054 </para>
16055 <para>
16056 <literal>json_array(SELECT * FROM (VALUES(1),(2)) t)</literal>
16057 <returnvalue>[1, 2]</returnvalue>
16058 </para></entry>
16059 </row>
16061 <row>
16062 <entry role="func_table_entry"><para role="func_signature">
16063 <indexterm>
16064 <primary>row_to_json</primary>
16065 </indexterm>
16066 <function>row_to_json</function> ( <type>record</type> <optional>, <type>boolean</type> </optional> )
16067 <returnvalue>json</returnvalue>
16068 </para>
16069 <para>
16070 Converts an SQL composite value to a JSON object. The behavior is the
16071 same as <function>to_json</function> except that line feeds will be
16072 added between top-level elements if the optional boolean parameter is
16073 true.
16074 </para>
16075 <para>
16076 <literal>row_to_json(row(1,'foo'))</literal>
16077 <returnvalue>{"f1":1,"f2":"foo"}</returnvalue>
16078 </para></entry>
16079 </row>
16081 <row>
16082 <entry role="func_table_entry"><para role="func_signature">
16083 <indexterm>
16084 <primary>json_build_array</primary>
16085 </indexterm>
16086 <function>json_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16087 <returnvalue>json</returnvalue>
16088 </para>
16089 <para role="func_signature">
16090 <indexterm>
16091 <primary>jsonb_build_array</primary>
16092 </indexterm>
16093 <function>jsonb_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16094 <returnvalue>jsonb</returnvalue>
16095 </para>
16096 <para>
16097 Builds a possibly-heterogeneously-typed JSON array out of a variadic
16098 argument list. Each argument is converted as
16099 per <function>to_json</function> or <function>to_jsonb</function>.
16100 </para>
16101 <para>
16102 <literal>json_build_array(1, 2, 'foo', 4, 5)</literal>
16103 <returnvalue>[1, 2, "foo", 4, 5]</returnvalue>
16104 </para></entry>
16105 </row>
16107 <row>
16108 <entry role="func_table_entry"><para role="func_signature">
16109 <indexterm>
16110 <primary>json_build_object</primary>
16111 </indexterm>
16112 <function>json_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16113 <returnvalue>json</returnvalue>
16114 </para>
16115 <para role="func_signature">
16116 <indexterm>
16117 <primary>jsonb_build_object</primary>
16118 </indexterm>
16119 <function>jsonb_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16120 <returnvalue>jsonb</returnvalue>
16121 </para>
16122 <para>
16123 Builds a JSON object out of a variadic argument list. By convention,
16124 the argument list consists of alternating keys and values. Key
16125 arguments are coerced to text; value arguments are converted as
16126 per <function>to_json</function> or <function>to_jsonb</function>.
16127 </para>
16128 <para>
16129 <literal>json_build_object('foo', 1, 2, row(3,'bar'))</literal>
16130 <returnvalue>{"foo" : 1, "2" : {"f1":3,"f2":"bar"}}</returnvalue>
16131 </para></entry>
16132 </row>
16134 <row>
16135 <entry role="func_table_entry"><para role="func_signature">
16136 <indexterm><primary>json_object</primary></indexterm>
16137 <function>json_object</function> (
16138 <optional> { <replaceable>key_expression</replaceable> { <literal>VALUE</literal> | ':' }
16139 <replaceable>value_expression</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> }<optional>, ...</optional> </optional>
16140 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
16141 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
16142 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
16143 </para>
16144 <para>
16145 Constructs a JSON object of all the key/value pairs given,
16146 or an empty object if none are given.
16147 <replaceable>key_expression</replaceable> is a scalar expression
16148 defining the <acronym>JSON</acronym> key, which is
16149 converted to the <type>text</type> type.
16150 It cannot be <literal>NULL</literal> nor can it
16151 belong to a type that has a cast to the <type>json</type> type.
16152 If <literal>WITH UNIQUE KEYS</literal> is specified, there must not
16153 be any duplicate <replaceable>key_expression</replaceable>.
16154 Any pair for which the <replaceable>value_expression</replaceable>
16155 evaluates to <literal>NULL</literal> is omitted from the output
16156 if <literal>ABSENT ON NULL</literal> is specified;
16157 if <literal>NULL ON NULL</literal> is specified or the clause
16158 omitted, the key is included with value <literal>NULL</literal>.
16159 </para>
16160 <para>
16161 <literal>json_object('code' VALUE 'P123', 'title': 'Jaws')</literal>
16162 <returnvalue>{"code" : "P123", "title" : "Jaws"}</returnvalue>
16163 </para></entry>
16164 </row>
16166 <row>
16167 <entry role="func_table_entry"><para role="func_signature">
16168 <indexterm>
16169 <primary>json_object</primary>
16170 </indexterm>
16171 <function>json_object</function> ( <type>text[]</type> )
16172 <returnvalue>json</returnvalue>
16173 </para>
16174 <para role="func_signature">
16175 <indexterm>
16176 <primary>jsonb_object</primary>
16177 </indexterm>
16178 <function>jsonb_object</function> ( <type>text[]</type> )
16179 <returnvalue>jsonb</returnvalue>
16180 </para>
16181 <para>
16182 Builds a JSON object out of a text array. The array must have either
16183 exactly one dimension with an even number of members, in which case
16184 they are taken as alternating key/value pairs, or two dimensions
16185 such that each inner array has exactly two elements, which
16186 are taken as a key/value pair. All values are converted to JSON
16187 strings.
16188 </para>
16189 <para>
16190 <literal>json_object('{a, 1, b, "def", c, 3.5}')</literal>
16191 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
16192 </para>
16193 <para><literal>json_object('{{a, 1}, {b, "def"}, {c, 3.5}}')</literal>
16194 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
16195 </para></entry>
16196 </row>
16198 <row>
16199 <entry role="func_table_entry"><para role="func_signature">
16200 <function>json_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
16201 <returnvalue>json</returnvalue>
16202 </para>
16203 <para role="func_signature">
16204 <function>jsonb_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
16205 <returnvalue>jsonb</returnvalue>
16206 </para>
16207 <para>
16208 This form of <function>json_object</function> takes keys and values
16209 pairwise from separate text arrays. Otherwise it is identical to
16210 the one-argument form.
16211 </para>
16212 <para>
16213 <literal>json_object('{a,b}', '{1,2}')</literal>
16214 <returnvalue>{"a": "1", "b": "2"}</returnvalue>
16215 </para></entry>
16216 </row>
16217 <row>
16218 <entry role="func_table_entry">
16219 <para role="func_signature">
16220 <indexterm><primary>json constructor</primary></indexterm>
16221 <function>json</function> (
16222 <replaceable>expression</replaceable>
16223 <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional></optional>
16224 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional></optional> )
16225 <returnvalue>json</returnvalue>
16226 </para>
16227 <para>
16228 Converts a given expression specified as <type>text</type> or
16229 <type>bytea</type> string (in UTF8 encoding) into a JSON
16230 value. If <replaceable>expression</replaceable> is NULL, an
16231 <acronym>SQL</acronym> null value is returned.
16232 If <literal>WITH UNIQUE</literal> is specified, the
16233 <replaceable>expression</replaceable> must not contain any duplicate
16234 object keys.
16235 </para>
16236 <para>
16237 <literal>json('{"a":123, "b":[true,"foo"], "a":"bar"}')</literal>
16238 <returnvalue>{"a":123, "b":[true,"foo"], "a":"bar"}</returnvalue>
16239 </para>
16240 </entry>
16241 </row>
16242 <row>
16243 <entry role="func_table_entry">
16244 <para role="func_signature">
16245 <indexterm><primary>json_scalar</primary></indexterm>
16246 <function>json_scalar</function> ( <replaceable>expression</replaceable> )
16247 </para>
16248 <para>
16249 Converts a given SQL scalar value into a JSON scalar value.
16250 If the input is NULL, an <acronym>SQL</acronym> null is returned. If
16251 the input is number or a boolean value, a corresponding JSON number
16252 or boolean value is returned. For any other value, a JSON string is
16253 returned.
16254 </para>
16255 <para>
16256 <literal>json_scalar(123.45)</literal>
16257 <returnvalue>123.45</returnvalue>
16258 </para>
16259 <para>
16260 <literal>json_scalar(CURRENT_TIMESTAMP)</literal>
16261 <returnvalue>"2022-05-10T10:51:04.62128-04:00"</returnvalue>
16262 </para></entry>
16263 </row>
16264 <row>
16265 <entry role="func_table_entry">
16266 <para role="func_signature">
16267 <function>json_serialize</function> (
16268 <replaceable>expression</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional>
16269 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional> )
16270 </para>
16271 <para>
16272 Converts an SQL/JSON expression into a character or binary string. The
16273 <replaceable>expression</replaceable> can be of any JSON type, any
16274 character string type, or <type>bytea</type> in UTF8 encoding.
16275 The returned type used in <literal> RETURNING</literal> can be any
16276 character string type or <type>bytea</type>. The default is
16277 <type>text</type>.
16278 </para>
16279 <para>
16280 <literal>json_serialize('{ "a" : 1 } ' RETURNING bytea)</literal>
16281 <returnvalue>\x7b20226122203a2031207d20</returnvalue>
16282 </para></entry>
16283 </row>
16284 </tbody>
16285 </tgroup>
16286 </table>
16288 <para>
16289 <xref linkend="functions-sqljson-misc" /> details SQL/JSON
16290 facilities for testing JSON.
16291 </para>
16293 <table id="functions-sqljson-misc">
16294 <title>SQL/JSON Testing Functions</title>
16295 <tgroup cols="1">
16296 <thead>
16297 <row>
16298 <entry role="func_table_entry"><para role="func_signature">
16299 Function signature
16300 </para>
16301 <para>
16302 Description
16303 </para>
16304 <para>
16305 Example(s)
16306 </para></entry>
16307 </row>
16308 </thead>
16309 <tbody>
16310 <row>
16311 <entry role="func_table_entry"><para role="func_signature">
16312 <indexterm><primary>IS JSON</primary></indexterm>
16313 <replaceable>expression</replaceable> <literal>IS</literal> <optional> <literal>NOT</literal> </optional> <literal>JSON</literal>
16314 <optional> { <literal>VALUE</literal> | <literal>SCALAR</literal> | <literal>ARRAY</literal> | <literal>OBJECT</literal> } </optional>
16315 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
16316 </para>
16317 <para>
16318 This predicate tests whether <replaceable>expression</replaceable> can be
16319 parsed as JSON, possibly of a specified type.
16320 If <literal>SCALAR</literal> or <literal>ARRAY</literal> or
16321 <literal>OBJECT</literal> is specified, the
16322 test is whether or not the JSON is of that particular type. If
16323 <literal>WITH UNIQUE KEYS</literal> is specified, then any object in the
16324 <replaceable>expression</replaceable> is also tested to see if it
16325 has duplicate keys.
16326 </para>
16327 <para>
16328 <programlisting>
16329 SELECT js,
16330 js IS JSON "json?",
16331 js IS JSON SCALAR "scalar?",
16332 js IS JSON OBJECT "object?",
16333 js IS JSON ARRAY "array?"
16334 FROM (VALUES
16335 ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'),('abc')) foo(js);
16336 js | json? | scalar? | object? | array?
16337 ------------+-------+---------+---------+--------
16338 123 | t | t | f | f
16339 "abc" | t | t | f | f
16340 {"a": "b"} | t | f | t | f
16341 [1,2] | t | f | f | t
16342 abc | f | f | f | f
16343 </programlisting>
16344 </para>
16345 <para>
16346 <programlisting>
16347 SELECT js,
16348 js IS JSON OBJECT "object?",
16349 js IS JSON ARRAY "array?",
16350 js IS JSON ARRAY WITH UNIQUE KEYS "array w. UK?",
16351 js IS JSON ARRAY WITHOUT UNIQUE KEYS "array w/o UK?"
16352 FROM (VALUES ('[{"a":"1"},
16353 {"b":"2","b":"3"}]')) foo(js);
16354 -[ RECORD 1 ]-+--------------------
16355 js | [{"a":"1"}, +
16356 | {"b":"2","b":"3"}]
16357 object? | f
16358 array? | t
16359 array w. UK? | f
16360 array w/o UK? | t
16361 </programlisting>
16362 </para></entry>
16363 </row>
16364 </tbody>
16365 </tgroup>
16366 </table>
16368 <para>
16369 <xref linkend="functions-json-processing-table"/> shows the functions that
16370 are available for processing <type>json</type> and <type>jsonb</type> values.
16371 </para>
16373 <table id="functions-json-processing-table">
16374 <title>JSON Processing Functions</title>
16375 <tgroup cols="1">
16376 <thead>
16377 <row>
16378 <entry role="func_table_entry"><para role="func_signature">
16379 Function
16380 </para>
16381 <para>
16382 Description
16383 </para>
16384 <para>
16385 Example(s)
16386 </para></entry>
16387 </row>
16388 </thead>
16390 <tbody>
16391 <row>
16392 <entry role="func_table_entry"><para role="func_signature">
16393 <indexterm>
16394 <primary>json_array_elements</primary>
16395 </indexterm>
16396 <function>json_array_elements</function> ( <type>json</type> )
16397 <returnvalue>setof json</returnvalue>
16398 </para>
16399 <para role="func_signature">
16400 <indexterm>
16401 <primary>jsonb_array_elements</primary>
16402 </indexterm>
16403 <function>jsonb_array_elements</function> ( <type>jsonb</type> )
16404 <returnvalue>setof jsonb</returnvalue>
16405 </para>
16406 <para>
16407 Expands the top-level JSON array into a set of JSON values.
16408 </para>
16409 <para>
16410 <literal>select * from json_array_elements('[1,true, [2,false]]')</literal>
16411 <returnvalue></returnvalue>
16412 <programlisting>
16413 value
16414 -----------
16416 true
16417 [2,false]
16418 </programlisting>
16419 </para></entry>
16420 </row>
16422 <row>
16423 <entry role="func_table_entry"><para role="func_signature">
16424 <indexterm>
16425 <primary>json_array_elements_text</primary>
16426 </indexterm>
16427 <function>json_array_elements_text</function> ( <type>json</type> )
16428 <returnvalue>setof text</returnvalue>
16429 </para>
16430 <para role="func_signature">
16431 <indexterm>
16432 <primary>jsonb_array_elements_text</primary>
16433 </indexterm>
16434 <function>jsonb_array_elements_text</function> ( <type>jsonb</type> )
16435 <returnvalue>setof text</returnvalue>
16436 </para>
16437 <para>
16438 Expands the top-level JSON array into a set of <type>text</type> values.
16439 </para>
16440 <para>
16441 <literal>select * from json_array_elements_text('["foo", "bar"]')</literal>
16442 <returnvalue></returnvalue>
16443 <programlisting>
16444 value
16445 -----------
16448 </programlisting>
16449 </para></entry>
16450 </row>
16452 <row>
16453 <entry role="func_table_entry"><para role="func_signature">
16454 <indexterm>
16455 <primary>json_array_length</primary>
16456 </indexterm>
16457 <function>json_array_length</function> ( <type>json</type> )
16458 <returnvalue>integer</returnvalue>
16459 </para>
16460 <para role="func_signature">
16461 <indexterm>
16462 <primary>jsonb_array_length</primary>
16463 </indexterm>
16464 <function>jsonb_array_length</function> ( <type>jsonb</type> )
16465 <returnvalue>integer</returnvalue>
16466 </para>
16467 <para>
16468 Returns the number of elements in the top-level JSON array.
16469 </para>
16470 <para>
16471 <literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal>
16472 <returnvalue>5</returnvalue>
16473 </para>
16474 <para>
16475 <literal>jsonb_array_length('[]')</literal>
16476 <returnvalue>0</returnvalue>
16477 </para></entry>
16478 </row>
16480 <row>
16481 <entry role="func_table_entry"><para role="func_signature">
16482 <indexterm>
16483 <primary>json_each</primary>
16484 </indexterm>
16485 <function>json_each</function> ( <type>json</type> )
16486 <returnvalue>setof record</returnvalue>
16487 ( <parameter>key</parameter> <type>text</type>,
16488 <parameter>value</parameter> <type>json</type> )
16489 </para>
16490 <para role="func_signature">
16491 <indexterm>
16492 <primary>jsonb_each</primary>
16493 </indexterm>
16494 <function>jsonb_each</function> ( <type>jsonb</type> )
16495 <returnvalue>setof record</returnvalue>
16496 ( <parameter>key</parameter> <type>text</type>,
16497 <parameter>value</parameter> <type>jsonb</type> )
16498 </para>
16499 <para>
16500 Expands the top-level JSON object into a set of key/value pairs.
16501 </para>
16502 <para>
16503 <literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal>
16504 <returnvalue></returnvalue>
16505 <programlisting>
16506 key | value
16507 -----+-------
16508 a | "foo"
16509 b | "bar"
16510 </programlisting>
16511 </para></entry>
16512 </row>
16514 <row>
16515 <entry role="func_table_entry"><para role="func_signature">
16516 <indexterm>
16517 <primary>json_each_text</primary>
16518 </indexterm>
16519 <function>json_each_text</function> ( <type>json</type> )
16520 <returnvalue>setof record</returnvalue>
16521 ( <parameter>key</parameter> <type>text</type>,
16522 <parameter>value</parameter> <type>text</type> )
16523 </para>
16524 <para role="func_signature">
16525 <indexterm>
16526 <primary>jsonb_each_text</primary>
16527 </indexterm>
16528 <function>jsonb_each_text</function> ( <type>jsonb</type> )
16529 <returnvalue>setof record</returnvalue>
16530 ( <parameter>key</parameter> <type>text</type>,
16531 <parameter>value</parameter> <type>text</type> )
16532 </para>
16533 <para>
16534 Expands the top-level JSON object into a set of key/value pairs.
16535 The returned <parameter>value</parameter>s will be of
16536 type <type>text</type>.
16537 </para>
16538 <para>
16539 <literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal>
16540 <returnvalue></returnvalue>
16541 <programlisting>
16542 key | value
16543 -----+-------
16544 a | foo
16545 b | bar
16546 </programlisting>
16547 </para></entry>
16548 </row>
16550 <row>
16551 <entry role="func_table_entry"><para role="func_signature">
16552 <indexterm>
16553 <primary>json_extract_path</primary>
16554 </indexterm>
16555 <function>json_extract_path</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16556 <returnvalue>json</returnvalue>
16557 </para>
16558 <para role="func_signature">
16559 <indexterm>
16560 <primary>jsonb_extract_path</primary>
16561 </indexterm>
16562 <function>jsonb_extract_path</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16563 <returnvalue>jsonb</returnvalue>
16564 </para>
16565 <para>
16566 Extracts JSON sub-object at the specified path.
16567 (This is functionally equivalent to the <literal>#&gt;</literal>
16568 operator, but writing the path out as a variadic list can be more
16569 convenient in some cases.)
16570 </para>
16571 <para>
16572 <literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
16573 <returnvalue>"foo"</returnvalue>
16574 </para></entry>
16575 </row>
16577 <row>
16578 <entry role="func_table_entry"><para role="func_signature">
16579 <indexterm>
16580 <primary>json_extract_path_text</primary>
16581 </indexterm>
16582 <function>json_extract_path_text</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16583 <returnvalue>text</returnvalue>
16584 </para>
16585 <para role="func_signature">
16586 <indexterm>
16587 <primary>jsonb_extract_path_text</primary>
16588 </indexterm>
16589 <function>jsonb_extract_path_text</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16590 <returnvalue>text</returnvalue>
16591 </para>
16592 <para>
16593 Extracts JSON sub-object at the specified path as <type>text</type>.
16594 (This is functionally equivalent to the <literal>#&gt;&gt;</literal>
16595 operator.)
16596 </para>
16597 <para>
16598 <literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
16599 <returnvalue>foo</returnvalue>
16600 </para></entry>
16601 </row>
16603 <row>
16604 <entry role="func_table_entry"><para role="func_signature">
16605 <indexterm>
16606 <primary>json_object_keys</primary>
16607 </indexterm>
16608 <function>json_object_keys</function> ( <type>json</type> )
16609 <returnvalue>setof text</returnvalue>
16610 </para>
16611 <para role="func_signature">
16612 <indexterm>
16613 <primary>jsonb_object_keys</primary>
16614 </indexterm>
16615 <function>jsonb_object_keys</function> ( <type>jsonb</type> )
16616 <returnvalue>setof text</returnvalue>
16617 </para>
16618 <para>
16619 Returns the set of keys in the top-level JSON object.
16620 </para>
16621 <para>
16622 <literal>select * from json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal>
16623 <returnvalue></returnvalue>
16624 <programlisting>
16625 json_object_keys
16626 ------------------
16629 </programlisting>
16630 </para></entry>
16631 </row>
16633 <row>
16634 <entry role="func_table_entry"><para role="func_signature">
16635 <indexterm>
16636 <primary>json_populate_record</primary>
16637 </indexterm>
16638 <function>json_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16639 <returnvalue>anyelement</returnvalue>
16640 </para>
16641 <para role="func_signature">
16642 <indexterm>
16643 <primary>jsonb_populate_record</primary>
16644 </indexterm>
16645 <function>jsonb_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16646 <returnvalue>anyelement</returnvalue>
16647 </para>
16648 <para>
16649 Expands the top-level JSON object to a row having the composite type
16650 of the <parameter>base</parameter> argument. The JSON object
16651 is scanned for fields whose names match column names of the output row
16652 type, and their values are inserted into those columns of the output.
16653 (Fields that do not correspond to any output column name are ignored.)
16654 In typical use, the value of <parameter>base</parameter> is just
16655 <literal>NULL</literal>, which means that any output columns that do
16656 not match any object field will be filled with nulls. However,
16657 if <parameter>base</parameter> isn't <literal>NULL</literal> then
16658 the values it contains will be used for unmatched columns.
16659 </para>
16660 <para>
16661 To convert a JSON value to the SQL type of an output column, the
16662 following rules are applied in sequence:
16663 <itemizedlist spacing="compact">
16664 <listitem>
16665 <para>
16666 A JSON null value is converted to an SQL null in all cases.
16667 </para>
16668 </listitem>
16669 <listitem>
16670 <para>
16671 If the output column is of type <type>json</type>
16672 or <type>jsonb</type>, the JSON value is just reproduced exactly.
16673 </para>
16674 </listitem>
16675 <listitem>
16676 <para>
16677 If the output column is a composite (row) type, and the JSON value
16678 is a JSON object, the fields of the object are converted to columns
16679 of the output row type by recursive application of these rules.
16680 </para>
16681 </listitem>
16682 <listitem>
16683 <para>
16684 Likewise, if the output column is an array type and the JSON value
16685 is a JSON array, the elements of the JSON array are converted to
16686 elements of the output array by recursive application of these
16687 rules.
16688 </para>
16689 </listitem>
16690 <listitem>
16691 <para>
16692 Otherwise, if the JSON value is a string, the contents of the
16693 string are fed to the input conversion function for the column's
16694 data type.
16695 </para>
16696 </listitem>
16697 <listitem>
16698 <para>
16699 Otherwise, the ordinary text representation of the JSON value is
16700 fed to the input conversion function for the column's data type.
16701 </para>
16702 </listitem>
16703 </itemizedlist>
16704 </para>
16705 <para>
16706 While the example below uses a constant JSON value, typical use would
16707 be to reference a <type>json</type> or <type>jsonb</type> column
16708 laterally from another table in the query's <literal>FROM</literal>
16709 clause. Writing <function>json_populate_record</function> in
16710 the <literal>FROM</literal> clause is good practice, since all of the
16711 extracted columns are available for use without duplicate function
16712 calls.
16713 </para>
16714 <para>
16715 <literal>create type subrowtype as (d int, e text);</literal>
16716 <literal>create type myrowtype as (a int, b text[], c subrowtype);</literal>
16717 </para>
16718 <para>
16719 <literal>select * from json_populate_record(null::myrowtype,
16720 '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}, "x": "foo"}')</literal>
16721 <returnvalue></returnvalue>
16722 <programlisting>
16723 a | b | c
16724 ---+-----------+-------------
16725 1 | {2,"a b"} | (4,"a b c")
16726 </programlisting>
16727 </para></entry>
16728 </row>
16730 <row>
16731 <entry role="func_table_entry"><para role="func_signature">
16732 <indexterm>
16733 <primary>json_populate_recordset</primary>
16734 </indexterm>
16735 <function>json_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16736 <returnvalue>setof anyelement</returnvalue>
16737 </para>
16738 <para role="func_signature">
16739 <indexterm>
16740 <primary>jsonb_populate_recordset</primary>
16741 </indexterm>
16742 <function>jsonb_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16743 <returnvalue>setof anyelement</returnvalue>
16744 </para>
16745 <para>
16746 Expands the top-level JSON array of objects to a set of rows having
16747 the composite type of the <parameter>base</parameter> argument.
16748 Each element of the JSON array is processed as described above
16749 for <function>json[b]_populate_record</function>.
16750 </para>
16751 <para>
16752 <literal>create type twoints as (a int, b int);</literal>
16753 </para>
16754 <para>
16755 <literal>select * from json_populate_recordset(null::twoints, '[{"a":1,"b":2}, {"a":3,"b":4}]')</literal>
16756 <returnvalue></returnvalue>
16757 <programlisting>
16758 a | b
16759 ---+---
16760 1 | 2
16761 3 | 4
16762 </programlisting>
16763 </para></entry>
16764 </row>
16766 <row>
16767 <entry role="func_table_entry"><para role="func_signature">
16768 <indexterm>
16769 <primary>json_to_record</primary>
16770 </indexterm>
16771 <function>json_to_record</function> ( <type>json</type> )
16772 <returnvalue>record</returnvalue>
16773 </para>
16774 <para role="func_signature">
16775 <indexterm>
16776 <primary>jsonb_to_record</primary>
16777 </indexterm>
16778 <function>jsonb_to_record</function> ( <type>jsonb</type> )
16779 <returnvalue>record</returnvalue>
16780 </para>
16781 <para>
16782 Expands the top-level JSON object to a row having the composite type
16783 defined by an <literal>AS</literal> clause. (As with all functions
16784 returning <type>record</type>, the calling query must explicitly
16785 define the structure of the record with an <literal>AS</literal>
16786 clause.) The output record is filled from fields of the JSON object,
16787 in the same way as described above
16788 for <function>json[b]_populate_record</function>. Since there is no
16789 input record value, unmatched columns are always filled with nulls.
16790 </para>
16791 <para>
16792 <literal>create type myrowtype as (a int, b text);</literal>
16793 </para>
16794 <para>
16795 <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>
16796 <returnvalue></returnvalue>
16797 <programlisting>
16798 a | b | c | d | r
16799 ---+---------+---------+---+---------------
16800 1 | [1,2,3] | {1,2,3} | | (123,"a b c")
16801 </programlisting>
16802 </para></entry>
16803 </row>
16805 <row>
16806 <entry role="func_table_entry"><para role="func_signature">
16807 <indexterm>
16808 <primary>json_to_recordset</primary>
16809 </indexterm>
16810 <function>json_to_recordset</function> ( <type>json</type> )
16811 <returnvalue>setof record</returnvalue>
16812 </para>
16813 <para role="func_signature">
16814 <indexterm>
16815 <primary>jsonb_to_recordset</primary>
16816 </indexterm>
16817 <function>jsonb_to_recordset</function> ( <type>jsonb</type> )
16818 <returnvalue>setof record</returnvalue>
16819 </para>
16820 <para>
16821 Expands the top-level JSON array of objects to a set of rows having
16822 the composite type defined by an <literal>AS</literal> clause. (As
16823 with all functions returning <type>record</type>, the calling query
16824 must explicitly define the structure of the record with
16825 an <literal>AS</literal> clause.) Each element of the JSON array is
16826 processed as described above
16827 for <function>json[b]_populate_record</function>.
16828 </para>
16829 <para>
16830 <literal>select * from json_to_recordset('[{"a":1,"b":"foo"}, {"a":"2","c":"bar"}]') as x(a int, b text)</literal>
16831 <returnvalue></returnvalue>
16832 <programlisting>
16833 a | b
16834 ---+-----
16835 1 | foo
16837 </programlisting>
16838 </para></entry>
16839 </row>
16841 <row>
16842 <entry role="func_table_entry"><para role="func_signature">
16843 <indexterm>
16844 <primary>jsonb_set</primary>
16845 </indexterm>
16846 <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> )
16847 <returnvalue>jsonb</returnvalue>
16848 </para>
16849 <para>
16850 Returns <parameter>target</parameter>
16851 with the item designated by <parameter>path</parameter>
16852 replaced by <parameter>new_value</parameter>, or with
16853 <parameter>new_value</parameter> added if
16854 <parameter>create_if_missing</parameter> is true (which is the
16855 default) and the item designated by <parameter>path</parameter>
16856 does not exist.
16857 All earlier steps in the path must exist, or
16858 the <parameter>target</parameter> is returned unchanged.
16859 As with the path oriented operators, negative integers that
16860 appear in the <parameter>path</parameter> count from the end
16861 of JSON arrays.
16862 If the last path step is an array index that is out of range,
16863 and <parameter>create_if_missing</parameter> is true, the new
16864 value is added at the beginning of the array if the index is negative,
16865 or at the end of the array if it is positive.
16866 </para>
16867 <para>
16868 <literal>jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', '[2,3,4]', false)</literal>
16869 <returnvalue>[{"f1": [2, 3, 4], "f2": null}, 2, null, 3]</returnvalue>
16870 </para>
16871 <para>
16872 <literal>jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}', '[2,3,4]')</literal>
16873 <returnvalue>[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</returnvalue>
16874 </para></entry>
16875 </row>
16877 <row>
16878 <entry role="func_table_entry"><para role="func_signature">
16879 <indexterm>
16880 <primary>jsonb_set_lax</primary>
16881 </indexterm>
16882 <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> )
16883 <returnvalue>jsonb</returnvalue>
16884 </para>
16885 <para>
16886 If <parameter>new_value</parameter> is not <literal>NULL</literal>,
16887 behaves identically to <literal>jsonb_set</literal>. Otherwise behaves
16888 according to the value
16889 of <parameter>null_value_treatment</parameter> which must be one
16890 of <literal>'raise_exception'</literal>,
16891 <literal>'use_json_null'</literal>, <literal>'delete_key'</literal>, or
16892 <literal>'return_target'</literal>. The default is
16893 <literal>'use_json_null'</literal>.
16894 </para>
16895 <para>
16896 <literal>jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null)</literal>
16897 <returnvalue>[{"f1": null, "f2": null}, 2, null, 3]</returnvalue>
16898 </para>
16899 <para>
16900 <literal>jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true, 'return_target')</literal>
16901 <returnvalue>[{"f1": 99, "f2": null}, 2]</returnvalue>
16902 </para></entry>
16903 </row>
16905 <row>
16906 <entry role="func_table_entry"><para role="func_signature">
16907 <indexterm>
16908 <primary>jsonb_insert</primary>
16909 </indexterm>
16910 <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> )
16911 <returnvalue>jsonb</returnvalue>
16912 </para>
16913 <para>
16914 Returns <parameter>target</parameter>
16915 with <parameter>new_value</parameter> inserted. If the item
16916 designated by the <parameter>path</parameter> is an array
16917 element, <parameter>new_value</parameter> will be inserted before
16918 that item if <parameter>insert_after</parameter> is false (which
16919 is the default), or after it
16920 if <parameter>insert_after</parameter> is true. If the item
16921 designated by the <parameter>path</parameter> is an object
16922 field, <parameter>new_value</parameter> will be inserted only if
16923 the object does not already contain that key.
16924 All earlier steps in the path must exist, or
16925 the <parameter>target</parameter> is returned unchanged.
16926 As with the path oriented operators, negative integers that
16927 appear in the <parameter>path</parameter> count from the end
16928 of JSON arrays.
16929 If the last path step is an array index that is out of range, the new
16930 value is added at the beginning of the array if the index is negative,
16931 or at the end of the array if it is positive.
16932 </para>
16933 <para>
16934 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')</literal>
16935 <returnvalue>{"a": [0, "new_value", 1, 2]}</returnvalue>
16936 </para>
16937 <para>
16938 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)</literal>
16939 <returnvalue>{"a": [0, 1, "new_value", 2]}</returnvalue>
16940 </para></entry>
16941 </row>
16943 <row>
16944 <entry role="func_table_entry"><para role="func_signature">
16945 <indexterm>
16946 <primary>json_strip_nulls</primary>
16947 </indexterm>
16948 <function>json_strip_nulls</function> ( <type>json</type> )
16949 <returnvalue>json</returnvalue>
16950 </para>
16951 <para role="func_signature">
16952 <indexterm>
16953 <primary>jsonb_strip_nulls</primary>
16954 </indexterm>
16955 <function>jsonb_strip_nulls</function> ( <type>jsonb</type> )
16956 <returnvalue>jsonb</returnvalue>
16957 </para>
16958 <para>
16959 Deletes all object fields that have null values from the given JSON
16960 value, recursively. Null values that are not object fields are
16961 untouched.
16962 </para>
16963 <para>
16964 <literal>json_strip_nulls('[{"f1":1, "f2":null}, 2, null, 3]')</literal>
16965 <returnvalue>[{"f1":1},2,null,3]</returnvalue>
16966 </para></entry>
16967 </row>
16969 <row>
16970 <entry role="func_table_entry"><para role="func_signature">
16971 <indexterm>
16972 <primary>jsonb_path_exists</primary>
16973 </indexterm>
16974 <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> )
16975 <returnvalue>boolean</returnvalue>
16976 </para>
16977 <para>
16978 Checks whether the JSON path returns any item for the specified JSON
16979 value.
16980 If the <parameter>vars</parameter> argument is specified, it must
16981 be a JSON object, and its fields provide named values to be
16982 substituted into the <type>jsonpath</type> expression.
16983 If the <parameter>silent</parameter> argument is specified and
16984 is <literal>true</literal>, the function suppresses the same errors
16985 as the <literal>@?</literal> and <literal>@@</literal> operators do.
16986 </para>
16987 <para>
16988 <literal>jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16989 <returnvalue>t</returnvalue>
16990 </para></entry>
16991 </row>
16993 <row>
16994 <entry role="func_table_entry"><para role="func_signature">
16995 <indexterm>
16996 <primary>jsonb_path_match</primary>
16997 </indexterm>
16998 <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> )
16999 <returnvalue>boolean</returnvalue>
17000 </para>
17001 <para>
17002 Returns the result of a JSON path predicate check for the specified
17003 JSON value. Only the first item of the result is taken into account.
17004 If the result is not Boolean, then <literal>NULL</literal> is returned.
17005 The optional <parameter>vars</parameter>
17006 and <parameter>silent</parameter> arguments act the same as
17007 for <function>jsonb_path_exists</function>.
17008 </para>
17009 <para>
17010 <literal>jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max))', '{"min":2, "max":4}')</literal>
17011 <returnvalue>t</returnvalue>
17012 </para></entry>
17013 </row>
17015 <row>
17016 <entry role="func_table_entry"><para role="func_signature">
17017 <indexterm>
17018 <primary>jsonb_path_query</primary>
17019 </indexterm>
17020 <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> )
17021 <returnvalue>setof jsonb</returnvalue>
17022 </para>
17023 <para>
17024 Returns all JSON items returned by the JSON path for the specified
17025 JSON value.
17026 The optional <parameter>vars</parameter>
17027 and <parameter>silent</parameter> arguments act the same as
17028 for <function>jsonb_path_exists</function>.
17029 </para>
17030 <para>
17031 <literal>select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
17032 <returnvalue></returnvalue>
17033 <programlisting>
17034 jsonb_path_query
17035 ------------------
17039 </programlisting>
17040 </para></entry>
17041 </row>
17043 <row>
17044 <entry role="func_table_entry"><para role="func_signature">
17045 <indexterm>
17046 <primary>jsonb_path_query_array</primary>
17047 </indexterm>
17048 <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> )
17049 <returnvalue>jsonb</returnvalue>
17050 </para>
17051 <para>
17052 Returns all JSON items returned by the JSON path for the specified
17053 JSON value, as a JSON array.
17054 The optional <parameter>vars</parameter>
17055 and <parameter>silent</parameter> arguments act the same as
17056 for <function>jsonb_path_exists</function>.
17057 </para>
17058 <para>
17059 <literal>jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
17060 <returnvalue>[2, 3, 4]</returnvalue>
17061 </para></entry>
17062 </row>
17064 <row>
17065 <entry role="func_table_entry"><para role="func_signature">
17066 <indexterm>
17067 <primary>jsonb_path_query_first</primary>
17068 </indexterm>
17069 <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> )
17070 <returnvalue>jsonb</returnvalue>
17071 </para>
17072 <para>
17073 Returns the first JSON item returned by the JSON path for the
17074 specified JSON value. Returns <literal>NULL</literal> if there are no
17075 results.
17076 The optional <parameter>vars</parameter>
17077 and <parameter>silent</parameter> arguments act the same as
17078 for <function>jsonb_path_exists</function>.
17079 </para>
17080 <para>
17081 <literal>jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
17082 <returnvalue>2</returnvalue>
17083 </para></entry>
17084 </row>
17086 <row>
17087 <entry role="func_table_entry"><para role="func_signature">
17088 <indexterm>
17089 <primary>jsonb_path_exists_tz</primary>
17090 </indexterm>
17091 <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> )
17092 <returnvalue>boolean</returnvalue>
17093 </para>
17094 <para role="func_signature">
17095 <indexterm>
17096 <primary>jsonb_path_match_tz</primary>
17097 </indexterm>
17098 <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> )
17099 <returnvalue>boolean</returnvalue>
17100 </para>
17101 <para role="func_signature">
17102 <indexterm>
17103 <primary>jsonb_path_query_tz</primary>
17104 </indexterm>
17105 <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> )
17106 <returnvalue>setof jsonb</returnvalue>
17107 </para>
17108 <para role="func_signature">
17109 <indexterm>
17110 <primary>jsonb_path_query_array_tz</primary>
17111 </indexterm>
17112 <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> )
17113 <returnvalue>jsonb</returnvalue>
17114 </para>
17115 <para role="func_signature">
17116 <indexterm>
17117 <primary>jsonb_path_query_first_tz</primary>
17118 </indexterm>
17119 <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> )
17120 <returnvalue>jsonb</returnvalue>
17121 </para>
17122 <para>
17123 These functions act like their counterparts described above without
17124 the <literal>_tz</literal> suffix, except that these functions support
17125 comparisons of date/time values that require timezone-aware
17126 conversions. The example below requires interpretation of the
17127 date-only value <literal>2015-08-02</literal> as a timestamp with time
17128 zone, so the result depends on the current
17129 <xref linkend="guc-timezone"/> setting. Due to this dependency, these
17130 functions are marked as stable, which means these functions cannot be
17131 used in indexes. Their counterparts are immutable, and so can be used
17132 in indexes; but they will throw errors if asked to make such
17133 comparisons.
17134 </para>
17135 <para>
17136 <literal>jsonb_path_exists_tz('["2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime() &lt; "2015-08-02".datetime())')</literal>
17137 <returnvalue>t</returnvalue>
17138 </para></entry>
17139 </row>
17141 <row>
17142 <entry role="func_table_entry"><para role="func_signature">
17143 <indexterm>
17144 <primary>jsonb_pretty</primary>
17145 </indexterm>
17146 <function>jsonb_pretty</function> ( <type>jsonb</type> )
17147 <returnvalue>text</returnvalue>
17148 </para>
17149 <para>
17150 Converts the given JSON value to pretty-printed, indented text.
17151 </para>
17152 <para>
17153 <literal>jsonb_pretty('[{"f1":1,"f2":null}, 2]')</literal>
17154 <returnvalue></returnvalue>
17155 <programlisting>
17158 "f1": 1,
17159 "f2": null
17163 </programlisting>
17164 </para></entry>
17165 </row>
17167 <row>
17168 <entry role="func_table_entry"><para role="func_signature">
17169 <indexterm>
17170 <primary>json_typeof</primary>
17171 </indexterm>
17172 <function>json_typeof</function> ( <type>json</type> )
17173 <returnvalue>text</returnvalue>
17174 </para>
17175 <para role="func_signature">
17176 <indexterm>
17177 <primary>jsonb_typeof</primary>
17178 </indexterm>
17179 <function>jsonb_typeof</function> ( <type>jsonb</type> )
17180 <returnvalue>text</returnvalue>
17181 </para>
17182 <para>
17183 Returns the type of the top-level JSON value as a text string.
17184 Possible types are
17185 <literal>object</literal>, <literal>array</literal>,
17186 <literal>string</literal>, <literal>number</literal>,
17187 <literal>boolean</literal>, and <literal>null</literal>.
17188 (The <literal>null</literal> result should not be confused
17189 with an SQL NULL; see the examples.)
17190 </para>
17191 <para>
17192 <literal>json_typeof('-123.4')</literal>
17193 <returnvalue>number</returnvalue>
17194 </para>
17195 <para>
17196 <literal>json_typeof('null'::json)</literal>
17197 <returnvalue>null</returnvalue>
17198 </para>
17199 <para>
17200 <literal>json_typeof(NULL::json) IS NULL</literal>
17201 <returnvalue>t</returnvalue>
17202 </para></entry>
17203 </row>
17204 </tbody>
17205 </tgroup>
17206 </table>
17207 </sect2>
17209 <sect2 id="functions-sqljson-path">
17210 <title>The SQL/JSON Path Language</title>
17212 <indexterm zone="functions-sqljson-path">
17213 <primary>SQL/JSON path language</primary>
17214 </indexterm>
17216 <para>
17217 SQL/JSON path expressions specify the items to be retrieved
17218 from the JSON data, similar to XPath expressions used
17219 for SQL access to XML. In <productname>PostgreSQL</productname>,
17220 path expressions are implemented as the <type>jsonpath</type>
17221 data type and can use any elements described in
17222 <xref linkend="datatype-jsonpath"/>.
17223 </para>
17225 <para>
17226 JSON query functions and operators
17227 pass the provided path expression to the <firstterm>path engine</firstterm>
17228 for evaluation. If the expression matches the queried JSON data,
17229 the corresponding JSON item, or set of items, is returned.
17230 Path expressions are written in the SQL/JSON path language
17231 and can include arithmetic expressions and functions.
17232 </para>
17234 <para>
17235 A path expression consists of a sequence of elements allowed
17236 by the <type>jsonpath</type> data type.
17237 The path expression is normally evaluated from left to right, but
17238 you can use parentheses to change the order of operations.
17239 If the evaluation is successful, a sequence of JSON items is produced,
17240 and the evaluation result is returned to the JSON query function
17241 that completes the specified computation.
17242 </para>
17244 <para>
17245 To refer to the JSON value being queried (the
17246 <firstterm>context item</firstterm>), use the <literal>$</literal> variable
17247 in the path expression. It can be followed by one or more
17248 <link linkend="type-jsonpath-accessors">accessor operators</link>,
17249 which go down the JSON structure level by level to retrieve sub-items
17250 of the context item. Each operator that follows deals with the
17251 result of the previous evaluation step.
17252 </para>
17254 <para>
17255 For example, suppose you have some JSON data from a GPS tracker that you
17256 would like to parse, such as:
17257 <programlisting>
17259 "track": {
17260 "segments": [
17262 "location": [ 47.763, 13.4034 ],
17263 "start time": "2018-10-14 10:05:14",
17264 "HR": 73
17267 "location": [ 47.706, 13.2635 ],
17268 "start time": "2018-10-14 10:39:21",
17269 "HR": 135
17274 </programlisting>
17275 </para>
17277 <para>
17278 To retrieve the available track segments, you need to use the
17279 <literal>.<replaceable>key</replaceable></literal> accessor
17280 operator to descend through surrounding JSON objects:
17281 <programlisting>
17282 $.track.segments
17283 </programlisting>
17284 </para>
17286 <para>
17287 To retrieve the contents of an array, you typically use the
17288 <literal>[*]</literal> operator. For example,
17289 the following path will return the location coordinates for all
17290 the available track segments:
17291 <programlisting>
17292 $.track.segments[*].location
17293 </programlisting>
17294 </para>
17296 <para>
17297 To return the coordinates of the first segment only, you can
17298 specify the corresponding subscript in the <literal>[]</literal>
17299 accessor operator. Recall that JSON array indexes are 0-relative:
17300 <programlisting>
17301 $.track.segments[0].location
17302 </programlisting>
17303 </para>
17305 <para>
17306 The result of each path evaluation step can be processed
17307 by one or more <type>jsonpath</type> operators and methods
17308 listed in <xref linkend="functions-sqljson-path-operators"/>.
17309 Each method name must be preceded by a dot. For example,
17310 you can get the size of an array:
17311 <programlisting>
17312 $.track.segments.size()
17313 </programlisting>
17314 More examples of using <type>jsonpath</type> operators
17315 and methods within path expressions appear below in
17316 <xref linkend="functions-sqljson-path-operators"/>.
17317 </para>
17319 <para>
17320 When defining a path, you can also use one or more
17321 <firstterm>filter expressions</firstterm> that work similarly to the
17322 <literal>WHERE</literal> clause in SQL. A filter expression begins with
17323 a question mark and provides a condition in parentheses:
17325 <programlisting>
17326 ? (<replaceable>condition</replaceable>)
17327 </programlisting>
17328 </para>
17330 <para>
17331 Filter expressions must be written just after the path evaluation step
17332 to which they should apply. The result of that step is filtered to include
17333 only those items that satisfy the provided condition. SQL/JSON defines
17334 three-valued logic, so the condition can be <literal>true</literal>, <literal>false</literal>,
17335 or <literal>unknown</literal>. The <literal>unknown</literal> value
17336 plays the same role as SQL <literal>NULL</literal> and can be tested
17337 for with the <literal>is unknown</literal> predicate. Further path
17338 evaluation steps use only those items for which the filter expression
17339 returned <literal>true</literal>.
17340 </para>
17342 <para>
17343 The functions and operators that can be used in filter expressions are
17344 listed in <xref linkend="functions-sqljson-filter-ex-table"/>. Within a
17345 filter expression, the <literal>@</literal> variable denotes the value
17346 being filtered (i.e., one result of the preceding path step). You can
17347 write accessor operators after <literal>@</literal> to retrieve component
17348 items.
17349 </para>
17351 <para>
17352 For example, suppose you would like to retrieve all heart rate values higher
17353 than 130. You can achieve this using the following expression:
17354 <programlisting>
17355 $.track.segments[*].HR ? (@ &gt; 130)
17356 </programlisting>
17357 </para>
17359 <para>
17360 To get the start times of segments with such values, you have to
17361 filter out irrelevant segments before returning the start times, so the
17362 filter expression is applied to the previous step, and the path used
17363 in the condition is different:
17364 <programlisting>
17365 $.track.segments[*] ? (@.HR &gt; 130)."start time"
17366 </programlisting>
17367 </para>
17369 <para>
17370 You can use several filter expressions in sequence, if required. For
17371 example, the following expression selects start times of all segments that
17372 contain locations with relevant coordinates and high heart rate values:
17373 <programlisting>
17374 $.track.segments[*] ? (@.location[1] &lt; 13.4) ? (@.HR &gt; 130)."start time"
17375 </programlisting>
17376 </para>
17378 <para>
17379 Using filter expressions at different nesting levels is also allowed.
17380 The following example first filters all segments by location, and then
17381 returns high heart rate values for these segments, if available:
17382 <programlisting>
17383 $.track.segments[*] ? (@.location[1] &lt; 13.4).HR ? (@ &gt; 130)
17384 </programlisting>
17385 </para>
17387 <para>
17388 You can also nest filter expressions within each other:
17389 <programlisting>
17390 $.track ? (exists(@.segments[*] ? (@.HR &gt; 130))).segments.size()
17391 </programlisting>
17392 This expression returns the size of the track if it contains any
17393 segments with high heart rate values, or an empty sequence otherwise.
17394 </para>
17396 <para>
17397 <productname>PostgreSQL</productname>'s implementation of the SQL/JSON path
17398 language has the following deviations from the SQL/JSON standard:
17399 </para>
17401 <itemizedlist>
17402 <listitem>
17403 <para>
17404 A path expression can be a Boolean predicate, although the SQL/JSON
17405 standard allows predicates only in filters. This is necessary for
17406 implementation of the <literal>@@</literal> operator. For example,
17407 the following <type>jsonpath</type> expression is valid in
17408 <productname>PostgreSQL</productname>:
17409 <programlisting>
17410 $.track.segments[*].HR &lt; 70
17411 </programlisting>
17412 </para>
17413 </listitem>
17415 <listitem>
17416 <para>
17417 There are minor differences in the interpretation of regular
17418 expression patterns used in <literal>like_regex</literal> filters, as
17419 described in <xref linkend="jsonpath-regular-expressions"/>.
17420 </para>
17421 </listitem>
17422 </itemizedlist>
17424 <sect3 id="strict-and-lax-modes">
17425 <title>Strict and Lax Modes</title>
17426 <para>
17427 When you query JSON data, the path expression may not match the
17428 actual JSON data structure. An attempt to access a non-existent
17429 member of an object or element of an array results in a
17430 structural error. SQL/JSON path expressions have two modes
17431 of handling structural errors:
17432 </para>
17434 <itemizedlist>
17435 <listitem>
17436 <para>
17437 lax (default) &mdash; the path engine implicitly adapts
17438 the queried data to the specified path.
17439 Any remaining structural errors are suppressed and converted
17440 to empty SQL/JSON sequences.
17441 </para>
17442 </listitem>
17443 <listitem>
17444 <para>
17445 strict &mdash; if a structural error occurs, an error is raised.
17446 </para>
17447 </listitem>
17448 </itemizedlist>
17450 <para>
17451 The lax mode facilitates matching of a JSON document structure and path
17452 expression if the JSON data does not conform to the expected schema.
17453 If an operand does not match the requirements of a particular operation,
17454 it can be automatically wrapped as an SQL/JSON array or unwrapped by
17455 converting its elements into an SQL/JSON sequence before performing
17456 this operation. Besides, comparison operators automatically unwrap their
17457 operands in the lax mode, so you can compare SQL/JSON arrays
17458 out-of-the-box. An array of size 1 is considered equal to its sole element.
17459 Automatic unwrapping is not performed only when:
17460 <itemizedlist>
17461 <listitem>
17462 <para>
17463 The path expression contains <literal>type()</literal> or
17464 <literal>size()</literal> methods that return the type
17465 and the number of elements in the array, respectively.
17466 </para>
17467 </listitem>
17468 <listitem>
17469 <para>
17470 The queried JSON data contain nested arrays. In this case, only
17471 the outermost array is unwrapped, while all the inner arrays
17472 remain unchanged. Thus, implicit unwrapping can only go one
17473 level down within each path evaluation step.
17474 </para>
17475 </listitem>
17476 </itemizedlist>
17477 </para>
17479 <para>
17480 For example, when querying the GPS data listed above, you can
17481 abstract from the fact that it stores an array of segments
17482 when using the lax mode:
17483 <programlisting>
17484 lax $.track.segments.location
17485 </programlisting>
17486 </para>
17488 <para>
17489 In the strict mode, the specified path must exactly match the structure of
17490 the queried JSON document to return an SQL/JSON item, so using this
17491 path expression will cause an error. To get the same result as in
17492 the lax mode, you have to explicitly unwrap the
17493 <literal>segments</literal> array:
17494 <programlisting>
17495 strict $.track.segments[*].location
17496 </programlisting>
17497 </para>
17499 <para>
17500 The <literal>.**</literal> accessor can lead to surprising results
17501 when using the lax mode. For instance, the following query selects every
17502 <literal>HR</literal> value twice:
17503 <programlisting>
17504 lax $.**.HR
17505 </programlisting>
17506 This happens because the <literal>.**</literal> accessor selects both
17507 the <literal>segments</literal> array and each of its elements, while
17508 the <literal>.HR</literal> accessor automatically unwraps arrays when
17509 using the lax mode. To avoid surprising results, we recommend using
17510 the <literal>.**</literal> accessor only in the strict mode. The
17511 following query selects each <literal>HR</literal> value just once:
17512 <programlisting>
17513 strict $.**.HR
17514 </programlisting>
17515 </para>
17517 </sect3>
17519 <sect3 id="functions-sqljson-path-operators">
17520 <title>SQL/JSON Path Operators and Methods</title>
17522 <para>
17523 <xref linkend="functions-sqljson-op-table"/> shows the operators and
17524 methods available in <type>jsonpath</type>. Note that while the unary
17525 operators and methods can be applied to multiple values resulting from a
17526 preceding path step, the binary operators (addition etc.) can only be
17527 applied to single values.
17528 </para>
17530 <table id="functions-sqljson-op-table">
17531 <title><type>jsonpath</type> Operators and Methods</title>
17532 <tgroup cols="1">
17533 <thead>
17534 <row>
17535 <entry role="func_table_entry"><para role="func_signature">
17536 Operator/Method
17537 </para>
17538 <para>
17539 Description
17540 </para>
17541 <para>
17542 Example(s)
17543 </para></entry>
17544 </row>
17545 </thead>
17547 <tbody>
17548 <row>
17549 <entry role="func_table_entry"><para role="func_signature">
17550 <replaceable>number</replaceable> <literal>+</literal> <replaceable>number</replaceable>
17551 <returnvalue><replaceable>number</replaceable></returnvalue>
17552 </para>
17553 <para>
17554 Addition
17555 </para>
17556 <para>
17557 <literal>jsonb_path_query('[2]', '$[0] + 3')</literal>
17558 <returnvalue>5</returnvalue>
17559 </para></entry>
17560 </row>
17562 <row>
17563 <entry role="func_table_entry"><para role="func_signature">
17564 <literal>+</literal> <replaceable>number</replaceable>
17565 <returnvalue><replaceable>number</replaceable></returnvalue>
17566 </para>
17567 <para>
17568 Unary plus (no operation); unlike addition, this can iterate over
17569 multiple values
17570 </para>
17571 <para>
17572 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '+ $.x')</literal>
17573 <returnvalue>[2, 3, 4]</returnvalue>
17574 </para></entry>
17575 </row>
17577 <row>
17578 <entry role="func_table_entry"><para role="func_signature">
17579 <replaceable>number</replaceable> <literal>-</literal> <replaceable>number</replaceable>
17580 <returnvalue><replaceable>number</replaceable></returnvalue>
17581 </para>
17582 <para>
17583 Subtraction
17584 </para>
17585 <para>
17586 <literal>jsonb_path_query('[2]', '7 - $[0]')</literal>
17587 <returnvalue>5</returnvalue>
17588 </para></entry>
17589 </row>
17591 <row>
17592 <entry role="func_table_entry"><para role="func_signature">
17593 <literal>-</literal> <replaceable>number</replaceable>
17594 <returnvalue><replaceable>number</replaceable></returnvalue>
17595 </para>
17596 <para>
17597 Negation; unlike subtraction, this can iterate over
17598 multiple values
17599 </para>
17600 <para>
17601 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '- $.x')</literal>
17602 <returnvalue>[-2, -3, -4]</returnvalue>
17603 </para></entry>
17604 </row>
17606 <row>
17607 <entry role="func_table_entry"><para role="func_signature">
17608 <replaceable>number</replaceable> <literal>*</literal> <replaceable>number</replaceable>
17609 <returnvalue><replaceable>number</replaceable></returnvalue>
17610 </para>
17611 <para>
17612 Multiplication
17613 </para>
17614 <para>
17615 <literal>jsonb_path_query('[4]', '2 * $[0]')</literal>
17616 <returnvalue>8</returnvalue>
17617 </para></entry>
17618 </row>
17620 <row>
17621 <entry role="func_table_entry"><para role="func_signature">
17622 <replaceable>number</replaceable> <literal>/</literal> <replaceable>number</replaceable>
17623 <returnvalue><replaceable>number</replaceable></returnvalue>
17624 </para>
17625 <para>
17626 Division
17627 </para>
17628 <para>
17629 <literal>jsonb_path_query('[8.5]', '$[0] / 2')</literal>
17630 <returnvalue>4.2500000000000000</returnvalue>
17631 </para></entry>
17632 </row>
17634 <row>
17635 <entry role="func_table_entry"><para role="func_signature">
17636 <replaceable>number</replaceable> <literal>%</literal> <replaceable>number</replaceable>
17637 <returnvalue><replaceable>number</replaceable></returnvalue>
17638 </para>
17639 <para>
17640 Modulo (remainder)
17641 </para>
17642 <para>
17643 <literal>jsonb_path_query('[32]', '$[0] % 10')</literal>
17644 <returnvalue>2</returnvalue>
17645 </para></entry>
17646 </row>
17648 <row>
17649 <entry role="func_table_entry"><para role="func_signature">
17650 <replaceable>value</replaceable> <literal>.</literal> <literal>type()</literal>
17651 <returnvalue><replaceable>string</replaceable></returnvalue>
17652 </para>
17653 <para>
17654 Type of the JSON item (see <function>json_typeof</function>)
17655 </para>
17656 <para>
17657 <literal>jsonb_path_query_array('[1, "2", {}]', '$[*].type()')</literal>
17658 <returnvalue>["number", "string", "object"]</returnvalue>
17659 </para></entry>
17660 </row>
17662 <row>
17663 <entry role="func_table_entry"><para role="func_signature">
17664 <replaceable>value</replaceable> <literal>.</literal> <literal>size()</literal>
17665 <returnvalue><replaceable>number</replaceable></returnvalue>
17666 </para>
17667 <para>
17668 Size of the JSON item (number of array elements, or 1 if not an
17669 array)
17670 </para>
17671 <para>
17672 <literal>jsonb_path_query('{"m": [11, 15]}', '$.m.size()')</literal>
17673 <returnvalue>2</returnvalue>
17674 </para></entry>
17675 </row>
17677 <row>
17678 <entry role="func_table_entry"><para role="func_signature">
17679 <replaceable>value</replaceable> <literal>.</literal> <literal>double()</literal>
17680 <returnvalue><replaceable>number</replaceable></returnvalue>
17681 </para>
17682 <para>
17683 Approximate floating-point number converted from a JSON number or
17684 string
17685 </para>
17686 <para>
17687 <literal>jsonb_path_query('{"len": "1.9"}', '$.len.double() * 2')</literal>
17688 <returnvalue>3.8</returnvalue>
17689 </para></entry>
17690 </row>
17692 <row>
17693 <entry role="func_table_entry"><para role="func_signature">
17694 <replaceable>number</replaceable> <literal>.</literal> <literal>ceiling()</literal>
17695 <returnvalue><replaceable>number</replaceable></returnvalue>
17696 </para>
17697 <para>
17698 Nearest integer greater than or equal to the given number
17699 </para>
17700 <para>
17701 <literal>jsonb_path_query('{"h": 1.3}', '$.h.ceiling()')</literal>
17702 <returnvalue>2</returnvalue>
17703 </para></entry>
17704 </row>
17706 <row>
17707 <entry role="func_table_entry"><para role="func_signature">
17708 <replaceable>number</replaceable> <literal>.</literal> <literal>floor()</literal>
17709 <returnvalue><replaceable>number</replaceable></returnvalue>
17710 </para>
17711 <para>
17712 Nearest integer less than or equal to the given number
17713 </para>
17714 <para>
17715 <literal>jsonb_path_query('{"h": 1.7}', '$.h.floor()')</literal>
17716 <returnvalue>1</returnvalue>
17717 </para></entry>
17718 </row>
17720 <row>
17721 <entry role="func_table_entry"><para role="func_signature">
17722 <replaceable>number</replaceable> <literal>.</literal> <literal>abs()</literal>
17723 <returnvalue><replaceable>number</replaceable></returnvalue>
17724 </para>
17725 <para>
17726 Absolute value of the given number
17727 </para>
17728 <para>
17729 <literal>jsonb_path_query('{"z": -0.3}', '$.z.abs()')</literal>
17730 <returnvalue>0.3</returnvalue>
17731 </para></entry>
17732 </row>
17734 <row>
17735 <entry role="func_table_entry"><para role="func_signature">
17736 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime()</literal>
17737 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
17738 (see note)
17739 </para>
17740 <para>
17741 Date/time value converted from a string
17742 </para>
17743 <para>
17744 <literal>jsonb_path_query('["2015-8-1", "2015-08-12"]', '$[*] ? (@.datetime() &lt; "2015-08-2".datetime())')</literal>
17745 <returnvalue>"2015-8-1"</returnvalue>
17746 </para></entry>
17747 </row>
17749 <row>
17750 <entry role="func_table_entry"><para role="func_signature">
17751 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime(<replaceable>template</replaceable>)</literal>
17752 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
17753 (see note)
17754 </para>
17755 <para>
17756 Date/time value converted from a string using the
17757 specified <function>to_timestamp</function> template
17758 </para>
17759 <para>
17760 <literal>jsonb_path_query_array('["12:30", "18:40"]', '$[*].datetime("HH24:MI")')</literal>
17761 <returnvalue>["12:30:00", "18:40:00"]</returnvalue>
17762 </para></entry>
17763 </row>
17765 <row>
17766 <entry role="func_table_entry"><para role="func_signature">
17767 <replaceable>object</replaceable> <literal>.</literal> <literal>keyvalue()</literal>
17768 <returnvalue><replaceable>array</replaceable></returnvalue>
17769 </para>
17770 <para>
17771 The object's key-value pairs, represented as an array of objects
17772 containing three fields: <literal>"key"</literal>,
17773 <literal>"value"</literal>, and <literal>"id"</literal>;
17774 <literal>"id"</literal> is a unique identifier of the object the
17775 key-value pair belongs to
17776 </para>
17777 <para>
17778 <literal>jsonb_path_query_array('{"x": "20", "y": 32}', '$.keyvalue()')</literal>
17779 <returnvalue>[{"id": 0, "key": "x", "value": "20"}, {"id": 0, "key": "y", "value": 32}]</returnvalue>
17780 </para></entry>
17781 </row>
17782 </tbody>
17783 </tgroup>
17784 </table>
17786 <note>
17787 <para>
17788 The result type of the <literal>datetime()</literal> and
17789 <literal>datetime(<replaceable>template</replaceable>)</literal>
17790 methods can be <type>date</type>, <type>timetz</type>, <type>time</type>,
17791 <type>timestamptz</type>, or <type>timestamp</type>.
17792 Both methods determine their result type dynamically.
17793 </para>
17794 <para>
17795 The <literal>datetime()</literal> method sequentially tries to
17796 match its input string to the ISO formats
17797 for <type>date</type>, <type>timetz</type>, <type>time</type>,
17798 <type>timestamptz</type>, and <type>timestamp</type>. It stops on
17799 the first matching format and emits the corresponding data type.
17800 </para>
17801 <para>
17802 The <literal>datetime(<replaceable>template</replaceable>)</literal>
17803 method determines the result type according to the fields used in the
17804 provided template string.
17805 </para>
17806 <para>
17807 The <literal>datetime()</literal> and
17808 <literal>datetime(<replaceable>template</replaceable>)</literal> methods
17809 use the same parsing rules as the <literal>to_timestamp</literal> SQL
17810 function does (see <xref linkend="functions-formatting"/>), with three
17811 exceptions. First, these methods don't allow unmatched template
17812 patterns. Second, only the following separators are allowed in the
17813 template string: minus sign, period, solidus (slash), comma, apostrophe,
17814 semicolon, colon and space. Third, separators in the template string
17815 must exactly match the input string.
17816 </para>
17817 <para>
17818 If different date/time types need to be compared, an implicit cast is
17819 applied. A <type>date</type> value can be cast to <type>timestamp</type>
17820 or <type>timestamptz</type>, <type>timestamp</type> can be cast to
17821 <type>timestamptz</type>, and <type>time</type> to <type>timetz</type>.
17822 However, all but the first of these conversions depend on the current
17823 <xref linkend="guc-timezone"/> setting, and thus can only be performed
17824 within timezone-aware <type>jsonpath</type> functions.
17825 </para>
17826 </note>
17828 <para>
17829 <xref linkend="functions-sqljson-filter-ex-table"/> shows the available
17830 filter expression elements.
17831 </para>
17833 <table id="functions-sqljson-filter-ex-table">
17834 <title><type>jsonpath</type> Filter Expression Elements</title>
17835 <tgroup cols="1">
17836 <thead>
17837 <row>
17838 <entry role="func_table_entry"><para role="func_signature">
17839 Predicate/Value
17840 </para>
17841 <para>
17842 Description
17843 </para>
17844 <para>
17845 Example(s)
17846 </para></entry>
17847 </row>
17848 </thead>
17850 <tbody>
17851 <row>
17852 <entry role="func_table_entry"><para role="func_signature">
17853 <replaceable>value</replaceable> <literal>==</literal> <replaceable>value</replaceable>
17854 <returnvalue>boolean</returnvalue>
17855 </para>
17856 <para>
17857 Equality comparison (this, and the other comparison operators, work on
17858 all JSON scalar values)
17859 </para>
17860 <para>
17861 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == 1)')</literal>
17862 <returnvalue>[1, 1]</returnvalue>
17863 </para>
17864 <para>
17865 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == "a")')</literal>
17866 <returnvalue>["a"]</returnvalue>
17867 </para></entry>
17868 </row>
17870 <row>
17871 <entry role="func_table_entry"><para role="func_signature">
17872 <replaceable>value</replaceable> <literal>!=</literal> <replaceable>value</replaceable>
17873 <returnvalue>boolean</returnvalue>
17874 </para>
17875 <para role="func_signature">
17876 <replaceable>value</replaceable> <literal>&lt;&gt;</literal> <replaceable>value</replaceable>
17877 <returnvalue>boolean</returnvalue>
17878 </para>
17879 <para>
17880 Non-equality comparison
17881 </para>
17882 <para>
17883 <literal>jsonb_path_query_array('[1, 2, 1, 3]', '$[*] ? (@ != 1)')</literal>
17884 <returnvalue>[2, 3]</returnvalue>
17885 </para>
17886 <para>
17887 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;&gt; "b")')</literal>
17888 <returnvalue>["a", "c"]</returnvalue>
17889 </para></entry>
17890 </row>
17892 <row>
17893 <entry role="func_table_entry"><para role="func_signature">
17894 <replaceable>value</replaceable> <literal>&lt;</literal> <replaceable>value</replaceable>
17895 <returnvalue>boolean</returnvalue>
17896 </para>
17897 <para>
17898 Less-than comparison
17899 </para>
17900 <para>
17901 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &lt; 2)')</literal>
17902 <returnvalue>[1]</returnvalue>
17903 </para></entry>
17904 </row>
17906 <row>
17907 <entry role="func_table_entry"><para role="func_signature">
17908 <replaceable>value</replaceable> <literal>&lt;=</literal> <replaceable>value</replaceable>
17909 <returnvalue>boolean</returnvalue>
17910 </para>
17911 <para>
17912 Less-than-or-equal-to comparison
17913 </para>
17914 <para>
17915 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;= "b")')</literal>
17916 <returnvalue>["a", "b"]</returnvalue>
17917 </para></entry>
17918 </row>
17920 <row>
17921 <entry role="func_table_entry"><para role="func_signature">
17922 <replaceable>value</replaceable> <literal>&gt;</literal> <replaceable>value</replaceable>
17923 <returnvalue>boolean</returnvalue>
17924 </para>
17925 <para>
17926 Greater-than comparison
17927 </para>
17928 <para>
17929 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt; 2)')</literal>
17930 <returnvalue>[3]</returnvalue>
17931 </para></entry>
17932 </row>
17934 <row>
17935 <entry role="func_table_entry"><para role="func_signature">
17936 <replaceable>value</replaceable> <literal>&gt;=</literal> <replaceable>value</replaceable>
17937 <returnvalue>boolean</returnvalue>
17938 </para>
17939 <para>
17940 Greater-than-or-equal-to comparison
17941 </para>
17942 <para>
17943 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt;= 2)')</literal>
17944 <returnvalue>[2, 3]</returnvalue>
17945 </para></entry>
17946 </row>
17948 <row>
17949 <entry role="func_table_entry"><para role="func_signature">
17950 <literal>true</literal>
17951 <returnvalue>boolean</returnvalue>
17952 </para>
17953 <para>
17954 JSON constant <literal>true</literal>
17955 </para>
17956 <para>
17957 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == true)')</literal>
17958 <returnvalue>{"name": "Chris", "parent": true}</returnvalue>
17959 </para></entry>
17960 </row>
17962 <row>
17963 <entry role="func_table_entry"><para role="func_signature">
17964 <literal>false</literal>
17965 <returnvalue>boolean</returnvalue>
17966 </para>
17967 <para>
17968 JSON constant <literal>false</literal>
17969 </para>
17970 <para>
17971 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == false)')</literal>
17972 <returnvalue>{"name": "John", "parent": false}</returnvalue>
17973 </para></entry>
17974 </row>
17976 <row>
17977 <entry role="func_table_entry"><para role="func_signature">
17978 <literal>null</literal>
17979 <returnvalue><replaceable>value</replaceable></returnvalue>
17980 </para>
17981 <para>
17982 JSON constant <literal>null</literal> (note that, unlike in SQL,
17983 comparison to <literal>null</literal> works normally)
17984 </para>
17985 <para>
17986 <literal>jsonb_path_query('[{"name": "Mary", "job": null}, {"name": "Michael", "job": "driver"}]', '$[*] ? (@.job == null) .name')</literal>
17987 <returnvalue>"Mary"</returnvalue>
17988 </para></entry>
17989 </row>
17991 <row>
17992 <entry role="func_table_entry"><para role="func_signature">
17993 <replaceable>boolean</replaceable> <literal>&amp;&amp;</literal> <replaceable>boolean</replaceable>
17994 <returnvalue>boolean</returnvalue>
17995 </para>
17996 <para>
17997 Boolean AND
17998 </para>
17999 <para>
18000 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &gt; 1 &amp;&amp; @ &lt; 5)')</literal>
18001 <returnvalue>3</returnvalue>
18002 </para></entry>
18003 </row>
18005 <row>
18006 <entry role="func_table_entry"><para role="func_signature">
18007 <replaceable>boolean</replaceable> <literal>||</literal> <replaceable>boolean</replaceable>
18008 <returnvalue>boolean</returnvalue>
18009 </para>
18010 <para>
18011 Boolean OR
18012 </para>
18013 <para>
18014 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &lt; 1 || @ &gt; 5)')</literal>
18015 <returnvalue>7</returnvalue>
18016 </para></entry>
18017 </row>
18019 <row>
18020 <entry role="func_table_entry"><para role="func_signature">
18021 <literal>!</literal> <replaceable>boolean</replaceable>
18022 <returnvalue>boolean</returnvalue>
18023 </para>
18024 <para>
18025 Boolean NOT
18026 </para>
18027 <para>
18028 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (!(@ &lt; 5))')</literal>
18029 <returnvalue>7</returnvalue>
18030 </para></entry>
18031 </row>
18033 <row>
18034 <entry role="func_table_entry"><para role="func_signature">
18035 <replaceable>boolean</replaceable> <literal>is unknown</literal>
18036 <returnvalue>boolean</returnvalue>
18037 </para>
18038 <para>
18039 Tests whether a Boolean condition is <literal>unknown</literal>.
18040 </para>
18041 <para>
18042 <literal>jsonb_path_query('[-1, 2, 7, "foo"]', '$[*] ? ((@ > 0) is unknown)')</literal>
18043 <returnvalue>"foo"</returnvalue>
18044 </para></entry>
18045 </row>
18047 <row>
18048 <entry role="func_table_entry"><para role="func_signature">
18049 <replaceable>string</replaceable> <literal>like_regex</literal> <replaceable>string</replaceable> <optional> <literal>flag</literal> <replaceable>string</replaceable> </optional>
18050 <returnvalue>boolean</returnvalue>
18051 </para>
18052 <para>
18053 Tests whether the first operand matches the regular expression
18054 given by the second operand, optionally with modifications
18055 described by a string of <literal>flag</literal> characters (see
18056 <xref linkend="jsonpath-regular-expressions"/>).
18057 </para>
18058 <para>
18059 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c")')</literal>
18060 <returnvalue>["abc", "abdacb"]</returnvalue>
18061 </para>
18062 <para>
18063 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c" flag "i")')</literal>
18064 <returnvalue>["abc", "aBdC", "abdacb"]</returnvalue>
18065 </para></entry>
18066 </row>
18068 <row>
18069 <entry role="func_table_entry"><para role="func_signature">
18070 <replaceable>string</replaceable> <literal>starts with</literal> <replaceable>string</replaceable>
18071 <returnvalue>boolean</returnvalue>
18072 </para>
18073 <para>
18074 Tests whether the second operand is an initial substring of the first
18075 operand.
18076 </para>
18077 <para>
18078 <literal>jsonb_path_query('["John Smith", "Mary Stone", "Bob Johnson"]', '$[*] ? (@ starts with "John")')</literal>
18079 <returnvalue>"John Smith"</returnvalue>
18080 </para></entry>
18081 </row>
18083 <row>
18084 <entry role="func_table_entry"><para role="func_signature">
18085 <literal>exists</literal> <literal>(</literal> <replaceable>path_expression</replaceable> <literal>)</literal>
18086 <returnvalue>boolean</returnvalue>
18087 </para>
18088 <para>
18089 Tests whether a path expression matches at least one SQL/JSON item.
18090 Returns <literal>unknown</literal> if the path expression would result
18091 in an error; the second example uses this to avoid a no-such-key error
18092 in strict mode.
18093 </para>
18094 <para>
18095 <literal>jsonb_path_query('{"x": [1, 2], "y": [2, 4]}', 'strict $.* ? (exists (@ ? (@[*] &gt; 2)))')</literal>
18096 <returnvalue>[2, 4]</returnvalue>
18097 </para>
18098 <para>
18099 <literal>jsonb_path_query_array('{"value": 41}', 'strict $ ? (exists (@.name)) .name')</literal>
18100 <returnvalue>[]</returnvalue>
18101 </para></entry>
18102 </row>
18103 </tbody>
18104 </tgroup>
18105 </table>
18107 </sect3>
18109 <sect3 id="jsonpath-regular-expressions">
18110 <title>SQL/JSON Regular Expressions</title>
18112 <indexterm zone="jsonpath-regular-expressions">
18113 <primary><literal>LIKE_REGEX</literal></primary>
18114 <secondary>in SQL/JSON</secondary>
18115 </indexterm>
18117 <para>
18118 SQL/JSON path expressions allow matching text to a regular expression
18119 with the <literal>like_regex</literal> filter. For example, the
18120 following SQL/JSON path query would case-insensitively match all
18121 strings in an array that start with an English vowel:
18122 <programlisting>
18123 $[*] ? (@ like_regex "^[aeiou]" flag "i")
18124 </programlisting>
18125 </para>
18127 <para>
18128 The optional <literal>flag</literal> string may include one or more of
18129 the characters
18130 <literal>i</literal> for case-insensitive match,
18131 <literal>m</literal> to allow <literal>^</literal>
18132 and <literal>$</literal> to match at newlines,
18133 <literal>s</literal> to allow <literal>.</literal> to match a newline,
18134 and <literal>q</literal> to quote the whole pattern (reducing the
18135 behavior to a simple substring match).
18136 </para>
18138 <para>
18139 The SQL/JSON standard borrows its definition for regular expressions
18140 from the <literal>LIKE_REGEX</literal> operator, which in turn uses the
18141 XQuery standard. PostgreSQL does not currently support the
18142 <literal>LIKE_REGEX</literal> operator. Therefore,
18143 the <literal>like_regex</literal> filter is implemented using the
18144 POSIX regular expression engine described in
18145 <xref linkend="functions-posix-regexp"/>. This leads to various minor
18146 discrepancies from standard SQL/JSON behavior, which are cataloged in
18147 <xref linkend="posix-vs-xquery"/>.
18148 Note, however, that the flag-letter incompatibilities described there
18149 do not apply to SQL/JSON, as it translates the XQuery flag letters to
18150 match what the POSIX engine expects.
18151 </para>
18153 <para>
18154 Keep in mind that the pattern argument of <literal>like_regex</literal>
18155 is a JSON path string literal, written according to the rules given in
18156 <xref linkend="datatype-jsonpath"/>. This means in particular that any
18157 backslashes you want to use in the regular expression must be doubled.
18158 For example, to match string values of the root document that contain
18159 only digits:
18160 <programlisting>
18161 $.* ? (@ like_regex "^\\d+$")
18162 </programlisting>
18163 </para>
18164 </sect3>
18165 </sect2>
18166 </sect1>
18168 <sect1 id="functions-sequence">
18169 <title>Sequence Manipulation Functions</title>
18171 <indexterm>
18172 <primary>sequence</primary>
18173 </indexterm>
18175 <para>
18176 This section describes functions for operating on <firstterm>sequence
18177 objects</firstterm>, also called sequence generators or just sequences.
18178 Sequence objects are special single-row tables created with <xref
18179 linkend="sql-createsequence"/>.
18180 Sequence objects are commonly used to generate unique identifiers
18181 for rows of a table. The sequence functions, listed in <xref
18182 linkend="functions-sequence-table"/>, provide simple, multiuser-safe
18183 methods for obtaining successive sequence values from sequence
18184 objects.
18185 </para>
18187 <table id="functions-sequence-table">
18188 <title>Sequence Functions</title>
18189 <tgroup cols="1">
18190 <thead>
18191 <row>
18192 <entry role="func_table_entry"><para role="func_signature">
18193 Function
18194 </para>
18195 <para>
18196 Description
18197 </para></entry>
18198 </row>
18199 </thead>
18201 <tbody>
18202 <row>
18203 <entry role="func_table_entry"><para role="func_signature">
18204 <indexterm>
18205 <primary>nextval</primary>
18206 </indexterm>
18207 <function>nextval</function> ( <type>regclass</type> )
18208 <returnvalue>bigint</returnvalue>
18209 </para>
18210 <para>
18211 Advances the sequence object to its next value and returns that value.
18212 This is done atomically: even if multiple sessions
18213 execute <function>nextval</function> concurrently, each will safely
18214 receive a distinct sequence value.
18215 If the sequence object has been created with default parameters,
18216 successive <function>nextval</function> calls will return successive
18217 values beginning with 1. Other behaviors can be obtained by using
18218 appropriate parameters in the <xref linkend="sql-createsequence"/>
18219 command.
18220 </para>
18221 <para>
18222 This function requires <literal>USAGE</literal>
18223 or <literal>UPDATE</literal> privilege on the sequence.
18224 </para></entry>
18225 </row>
18227 <row>
18228 <entry role="func_table_entry"><para role="func_signature">
18229 <indexterm>
18230 <primary>setval</primary>
18231 </indexterm>
18232 <function>setval</function> ( <type>regclass</type>, <type>bigint</type> <optional>, <type>boolean</type> </optional> )
18233 <returnvalue>bigint</returnvalue>
18234 </para>
18235 <para>
18236 Sets the sequence object's current value, and optionally
18237 its <literal>is_called</literal> flag. The two-parameter
18238 form sets the sequence's <literal>last_value</literal> field to the
18239 specified value and sets its <literal>is_called</literal> field to
18240 <literal>true</literal>, meaning that the next
18241 <function>nextval</function> will advance the sequence before
18242 returning a value. The value that will be reported
18243 by <function>currval</function> is also set to the specified value.
18244 In the three-parameter form, <literal>is_called</literal> can be set
18245 to either <literal>true</literal>
18246 or <literal>false</literal>. <literal>true</literal> has the same
18247 effect as the two-parameter form. If it is set
18248 to <literal>false</literal>, the next <function>nextval</function>
18249 will return exactly the specified value, and sequence advancement
18250 commences with the following <function>nextval</function>.
18251 Furthermore, the value reported by <function>currval</function> is not
18252 changed in this case. For example,
18253 <programlisting>
18254 SELECT setval('myseq', 42); <lineannotation>Next <function>nextval</function> will return 43</lineannotation>
18255 SELECT setval('myseq', 42, true); <lineannotation>Same as above</lineannotation>
18256 SELECT setval('myseq', 42, false); <lineannotation>Next <function>nextval</function> will return 42</lineannotation>
18257 </programlisting>
18258 The result returned by <function>setval</function> is just the value of its
18259 second argument.
18260 </para>
18261 <para>
18262 This function requires <literal>UPDATE</literal> privilege on the
18263 sequence.
18264 </para></entry>
18265 </row>
18267 <row>
18268 <entry role="func_table_entry"><para role="func_signature">
18269 <indexterm>
18270 <primary>currval</primary>
18271 </indexterm>
18272 <function>currval</function> ( <type>regclass</type> )
18273 <returnvalue>bigint</returnvalue>
18274 </para>
18275 <para>
18276 Returns the value most recently obtained
18277 by <function>nextval</function> for this sequence in the current
18278 session. (An error is reported if <function>nextval</function> has
18279 never been called for this sequence in this session.) Because this is
18280 returning a session-local value, it gives a predictable answer whether
18281 or not other sessions have executed <function>nextval</function> since
18282 the current session did.
18283 </para>
18284 <para>
18285 This function requires <literal>USAGE</literal>
18286 or <literal>SELECT</literal> privilege on the sequence.
18287 </para></entry>
18288 </row>
18290 <row>
18291 <entry role="func_table_entry"><para role="func_signature">
18292 <indexterm>
18293 <primary>lastval</primary>
18294 </indexterm>
18295 <function>lastval</function> ()
18296 <returnvalue>bigint</returnvalue>
18297 </para>
18298 <para>
18299 Returns the value most recently returned by
18300 <function>nextval</function> in the current session. This function is
18301 identical to <function>currval</function>, except that instead
18302 of taking the sequence name as an argument it refers to whichever
18303 sequence <function>nextval</function> was most recently applied to
18304 in the current session. It is an error to call
18305 <function>lastval</function> if <function>nextval</function>
18306 has not yet been called in the current session.
18307 </para>
18308 <para>
18309 This function requires <literal>USAGE</literal>
18310 or <literal>SELECT</literal> privilege on the last used sequence.
18311 </para></entry>
18312 </row>
18313 </tbody>
18314 </tgroup>
18315 </table>
18317 <caution>
18318 <para>
18319 To avoid blocking concurrent transactions that obtain numbers from
18320 the same sequence, the value obtained by <function>nextval</function>
18321 is not reclaimed for re-use if the calling transaction later aborts.
18322 This means that transaction aborts or database crashes can result in
18323 gaps in the sequence of assigned values. That can happen without a
18324 transaction abort, too. For example an <command>INSERT</command> with
18325 an <literal>ON CONFLICT</literal> clause will compute the to-be-inserted
18326 tuple, including doing any required <function>nextval</function>
18327 calls, before detecting any conflict that would cause it to follow
18328 the <literal>ON CONFLICT</literal> rule instead.
18329 Thus, <productname>PostgreSQL</productname> sequence
18330 objects <emphasis>cannot be used to obtain <quote>gapless</quote>
18331 sequences</emphasis>.
18332 </para>
18334 <para>
18335 Likewise, sequence state changes made by <function>setval</function>
18336 are immediately visible to other transactions, and are not undone if
18337 the calling transaction rolls back.
18338 </para>
18340 <para>
18341 If the database cluster crashes before committing a transaction
18342 containing a <function>nextval</function>
18343 or <function>setval</function> call, the sequence state change might
18344 not have made its way to persistent storage, so that it is uncertain
18345 whether the sequence will have its original or updated state after the
18346 cluster restarts. This is harmless for usage of the sequence within
18347 the database, since other effects of uncommitted transactions will not
18348 be visible either. However, if you wish to use a sequence value for
18349 persistent outside-the-database purposes, make sure that the
18350 <function>nextval</function> call has been committed before doing so.
18351 </para>
18352 </caution>
18354 <para>
18355 The sequence to be operated on by a sequence function is specified by
18356 a <type>regclass</type> argument, which is simply the OID of the sequence in the
18357 <structname>pg_class</structname> system catalog. You do not have to look up the
18358 OID by hand, however, since the <type>regclass</type> data type's input
18359 converter will do the work for you. See <xref linkend="datatype-oid"/>
18360 for details.
18361 </para>
18362 </sect1>
18365 <sect1 id="functions-conditional">
18366 <title>Conditional Expressions</title>
18368 <indexterm>
18369 <primary>CASE</primary>
18370 </indexterm>
18372 <indexterm>
18373 <primary>conditional expression</primary>
18374 </indexterm>
18376 <para>
18377 This section describes the <acronym>SQL</acronym>-compliant conditional expressions
18378 available in <productname>PostgreSQL</productname>.
18379 </para>
18381 <tip>
18382 <para>
18383 If your needs go beyond the capabilities of these conditional
18384 expressions, you might want to consider writing a server-side function
18385 in a more expressive programming language.
18386 </para>
18387 </tip>
18389 <note>
18390 <para>
18391 Although <token>COALESCE</token>, <token>GREATEST</token>, and
18392 <token>LEAST</token> are syntactically similar to functions, they are
18393 not ordinary functions, and thus cannot be used with explicit
18394 <token>VARIADIC</token> array arguments.
18395 </para>
18396 </note>
18398 <sect2 id="functions-case">
18399 <title><literal>CASE</literal></title>
18401 <para>
18402 The <acronym>SQL</acronym> <token>CASE</token> expression is a
18403 generic conditional expression, similar to if/else statements in
18404 other programming languages:
18406 <synopsis>
18407 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
18408 <optional>WHEN ...</optional>
18409 <optional>ELSE <replaceable>result</replaceable></optional>
18411 </synopsis>
18413 <token>CASE</token> clauses can be used wherever
18414 an expression is valid. Each <replaceable>condition</replaceable> is an
18415 expression that returns a <type>boolean</type> result. If the condition's
18416 result is true, the value of the <token>CASE</token> expression is the
18417 <replaceable>result</replaceable> that follows the condition, and the
18418 remainder of the <token>CASE</token> expression is not processed. If the
18419 condition's result is not true, any subsequent <token>WHEN</token> clauses
18420 are examined in the same manner. If no <token>WHEN</token>
18421 <replaceable>condition</replaceable> yields true, the value of the
18422 <token>CASE</token> expression is the <replaceable>result</replaceable> of the
18423 <token>ELSE</token> clause. If the <token>ELSE</token> clause is
18424 omitted and no condition is true, the result is null.
18425 </para>
18427 <para>
18428 An example:
18429 <screen>
18430 SELECT * FROM test;
18439 SELECT a,
18440 CASE WHEN a=1 THEN 'one'
18441 WHEN a=2 THEN 'two'
18442 ELSE 'other'
18444 FROM test;
18446 a | case
18447 ---+-------
18448 1 | one
18449 2 | two
18450 3 | other
18451 </screen>
18452 </para>
18454 <para>
18455 The data types of all the <replaceable>result</replaceable>
18456 expressions must be convertible to a single output type.
18457 See <xref linkend="typeconv-union-case"/> for more details.
18458 </para>
18460 <para>
18461 There is a <quote>simple</quote> form of <token>CASE</token> expression
18462 that is a variant of the general form above:
18464 <synopsis>
18465 CASE <replaceable>expression</replaceable>
18466 WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
18467 <optional>WHEN ...</optional>
18468 <optional>ELSE <replaceable>result</replaceable></optional>
18470 </synopsis>
18472 The first
18473 <replaceable>expression</replaceable> is computed, then compared to
18474 each of the <replaceable>value</replaceable> expressions in the
18475 <token>WHEN</token> clauses until one is found that is equal to it. If
18476 no match is found, the <replaceable>result</replaceable> of the
18477 <token>ELSE</token> clause (or a null value) is returned. This is similar
18478 to the <function>switch</function> statement in C.
18479 </para>
18481 <para>
18482 The example above can be written using the simple
18483 <token>CASE</token> syntax:
18484 <screen>
18485 SELECT a,
18486 CASE a WHEN 1 THEN 'one'
18487 WHEN 2 THEN 'two'
18488 ELSE 'other'
18490 FROM test;
18492 a | case
18493 ---+-------
18494 1 | one
18495 2 | two
18496 3 | other
18497 </screen>
18498 </para>
18500 <para>
18501 A <token>CASE</token> expression does not evaluate any subexpressions
18502 that are not needed to determine the result. For example, this is a
18503 possible way of avoiding a division-by-zero failure:
18504 <programlisting>
18505 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
18506 </programlisting>
18507 </para>
18509 <note>
18510 <para>
18511 As described in <xref linkend="syntax-express-eval"/>, there are various
18512 situations in which subexpressions of an expression are evaluated at
18513 different times, so that the principle that <quote><token>CASE</token>
18514 evaluates only necessary subexpressions</quote> is not ironclad. For
18515 example a constant <literal>1/0</literal> subexpression will usually result in
18516 a division-by-zero failure at planning time, even if it's within
18517 a <token>CASE</token> arm that would never be entered at run time.
18518 </para>
18519 </note>
18520 </sect2>
18522 <sect2 id="functions-coalesce-nvl-ifnull">
18523 <title><literal>COALESCE</literal></title>
18525 <indexterm>
18526 <primary>COALESCE</primary>
18527 </indexterm>
18529 <indexterm>
18530 <primary>NVL</primary>
18531 </indexterm>
18533 <indexterm>
18534 <primary>IFNULL</primary>
18535 </indexterm>
18537 <synopsis>
18538 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18539 </synopsis>
18541 <para>
18542 The <function>COALESCE</function> function returns the first of its
18543 arguments that is not null. Null is returned only if all arguments
18544 are null. It is often used to substitute a default value for
18545 null values when data is retrieved for display, for example:
18546 <programlisting>
18547 SELECT COALESCE(description, short_description, '(none)') ...
18548 </programlisting>
18549 This returns <varname>description</varname> if it is not null, otherwise
18550 <varname>short_description</varname> if it is not null, otherwise <literal>(none)</literal>.
18551 </para>
18553 <para>
18554 The arguments must all be convertible to a common data type, which
18555 will be the type of the result (see
18556 <xref linkend="typeconv-union-case"/> for details).
18557 </para>
18559 <para>
18560 Like a <token>CASE</token> expression, <function>COALESCE</function> only
18561 evaluates the arguments that are needed to determine the result;
18562 that is, arguments to the right of the first non-null argument are
18563 not evaluated. This SQL-standard function provides capabilities similar
18564 to <function>NVL</function> and <function>IFNULL</function>, which are used in some other
18565 database systems.
18566 </para>
18567 </sect2>
18569 <sect2 id="functions-nullif">
18570 <title><literal>NULLIF</literal></title>
18572 <indexterm>
18573 <primary>NULLIF</primary>
18574 </indexterm>
18576 <synopsis>
18577 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
18578 </synopsis>
18580 <para>
18581 The <function>NULLIF</function> function returns a null value if
18582 <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
18583 otherwise it returns <replaceable>value1</replaceable>.
18584 This can be used to perform the inverse operation of the
18585 <function>COALESCE</function> example given above:
18586 <programlisting>
18587 SELECT NULLIF(value, '(none)') ...
18588 </programlisting>
18589 In this example, if <literal>value</literal> is <literal>(none)</literal>,
18590 null is returned, otherwise the value of <literal>value</literal>
18591 is returned.
18592 </para>
18594 <para>
18595 The two arguments must be of comparable types.
18596 To be specific, they are compared exactly as if you had
18597 written <literal><replaceable>value1</replaceable>
18598 = <replaceable>value2</replaceable></literal>, so there must be a
18599 suitable <literal>=</literal> operator available.
18600 </para>
18602 <para>
18603 The result has the same type as the first argument &mdash; but there is
18604 a subtlety. What is actually returned is the first argument of the
18605 implied <literal>=</literal> operator, and in some cases that will have
18606 been promoted to match the second argument's type. For
18607 example, <literal>NULLIF(1, 2.2)</literal> yields <type>numeric</type>,
18608 because there is no <type>integer</type> <literal>=</literal>
18609 <type>numeric</type> operator,
18610 only <type>numeric</type> <literal>=</literal> <type>numeric</type>.
18611 </para>
18613 </sect2>
18615 <sect2 id="functions-greatest-least">
18616 <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
18618 <indexterm>
18619 <primary>GREATEST</primary>
18620 </indexterm>
18621 <indexterm>
18622 <primary>LEAST</primary>
18623 </indexterm>
18625 <synopsis>
18626 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18627 </synopsis>
18628 <synopsis>
18629 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18630 </synopsis>
18632 <para>
18633 The <function>GREATEST</function> and <function>LEAST</function> functions select the
18634 largest or smallest value from a list of any number of expressions.
18635 The expressions must all be convertible to a common data type, which
18636 will be the type of the result
18637 (see <xref linkend="typeconv-union-case"/> for details).
18638 </para>
18640 <para>
18641 NULL values in the argument list are ignored. The result will be NULL
18642 only if all the expressions evaluate to NULL. (This is a deviation from
18643 the SQL standard. According to the standard, the return value is NULL if
18644 any argument is NULL. Some other databases behave this way.)
18645 </para>
18646 </sect2>
18647 </sect1>
18649 <sect1 id="functions-array">
18650 <title>Array Functions and Operators</title>
18652 <para>
18653 <xref linkend="array-operators-table"/> shows the specialized operators
18654 available for array types.
18655 In addition to those, the usual comparison operators shown in <xref
18656 linkend="functions-comparison-op-table"/> are available for
18657 arrays. The comparison operators compare the array contents
18658 element-by-element, using the default B-tree comparison function for
18659 the element data type, and sort based on the first difference.
18660 In multidimensional arrays the elements are visited in row-major order
18661 (last subscript varies most rapidly).
18662 If the contents of two arrays are equal but the dimensionality is
18663 different, the first difference in the dimensionality information
18664 determines the sort order.
18665 </para>
18667 <table id="array-operators-table">
18668 <title>Array Operators</title>
18669 <tgroup cols="1">
18670 <thead>
18671 <row>
18672 <entry role="func_table_entry"><para role="func_signature">
18673 Operator
18674 </para>
18675 <para>
18676 Description
18677 </para>
18678 <para>
18679 Example(s)
18680 </para></entry>
18681 </row>
18682 </thead>
18684 <tbody>
18685 <row>
18686 <entry role="func_table_entry"><para role="func_signature">
18687 <type>anyarray</type> <literal>@&gt;</literal> <type>anyarray</type>
18688 <returnvalue>boolean</returnvalue>
18689 </para>
18690 <para>
18691 Does the first array contain the second, that is, does each element
18692 appearing in the second array equal some element of the first array?
18693 (Duplicates are not treated specially,
18694 thus <literal>ARRAY[1]</literal> and <literal>ARRAY[1,1]</literal> are
18695 each considered to contain the other.)
18696 </para>
18697 <para>
18698 <literal>ARRAY[1,4,3] @&gt; ARRAY[3,1,3]</literal>
18699 <returnvalue>t</returnvalue>
18700 </para></entry>
18701 </row>
18703 <row>
18704 <entry role="func_table_entry"><para role="func_signature">
18705 <type>anyarray</type> <literal>&lt;@</literal> <type>anyarray</type>
18706 <returnvalue>boolean</returnvalue>
18707 </para>
18708 <para>
18709 Is the first array contained by the second?
18710 </para>
18711 <para>
18712 <literal>ARRAY[2,2,7] &lt;@ ARRAY[1,7,4,2,6]</literal>
18713 <returnvalue>t</returnvalue>
18714 </para></entry>
18715 </row>
18717 <row>
18718 <entry role="func_table_entry"><para role="func_signature">
18719 <type>anyarray</type> <literal>&amp;&amp;</literal> <type>anyarray</type>
18720 <returnvalue>boolean</returnvalue>
18721 </para>
18722 <para>
18723 Do the arrays overlap, that is, have any elements in common?
18724 </para>
18725 <para>
18726 <literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal>
18727 <returnvalue>t</returnvalue>
18728 </para></entry>
18729 </row>
18731 <row>
18732 <entry role="func_table_entry"><para role="func_signature">
18733 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
18734 <returnvalue>anycompatiblearray</returnvalue>
18735 </para>
18736 <para>
18737 Concatenates the two arrays. Concatenating a null or empty array is a
18738 no-op; otherwise the arrays must have the same number of dimensions
18739 (as illustrated by the first example) or differ in number of
18740 dimensions by one (as illustrated by the second).
18741 If the arrays are not of identical element types, they will be coerced
18742 to a common type (see <xref linkend="typeconv-union-case"/>).
18743 </para>
18744 <para>
18745 <literal>ARRAY[1,2,3] || ARRAY[4,5,6,7]</literal>
18746 <returnvalue>{1,2,3,4,5,6,7}</returnvalue>
18747 </para>
18748 <para>
18749 <literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9.9]]</literal>
18750 <returnvalue>{{1,2,3},{4,5,6},{7,8,9.9}}</returnvalue>
18751 </para></entry>
18752 </row>
18754 <row>
18755 <entry role="func_table_entry"><para role="func_signature">
18756 <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
18757 <returnvalue>anycompatiblearray</returnvalue>
18758 </para>
18759 <para>
18760 Concatenates an element onto the front of an array (which must be
18761 empty or one-dimensional).
18762 </para>
18763 <para>
18764 <literal>3 || ARRAY[4,5,6]</literal>
18765 <returnvalue>{3,4,5,6}</returnvalue>
18766 </para></entry>
18767 </row>
18769 <row>
18770 <entry role="func_table_entry"><para role="func_signature">
18771 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
18772 <returnvalue>anycompatiblearray</returnvalue>
18773 </para>
18774 <para>
18775 Concatenates an element onto the end of an array (which must be
18776 empty or one-dimensional).
18777 </para>
18778 <para>
18779 <literal>ARRAY[4,5,6] || 7</literal>
18780 <returnvalue>{4,5,6,7}</returnvalue>
18781 </para></entry>
18782 </row>
18783 </tbody>
18784 </tgroup>
18785 </table>
18787 <para>
18788 See <xref linkend="arrays"/> for more details about array operator
18789 behavior. See <xref linkend="indexes-types"/> for more details about
18790 which operators support indexed operations.
18791 </para>
18793 <para>
18794 <xref linkend="array-functions-table"/> shows the functions
18795 available for use with array types. See <xref linkend="arrays"/>
18796 for more information and examples of the use of these functions.
18797 </para>
18799 <table id="array-functions-table">
18800 <title>Array Functions</title>
18801 <tgroup cols="1">
18802 <thead>
18803 <row>
18804 <entry role="func_table_entry"><para role="func_signature">
18805 Function
18806 </para>
18807 <para>
18808 Description
18809 </para>
18810 <para>
18811 Example(s)
18812 </para></entry>
18813 </row>
18814 </thead>
18816 <tbody>
18817 <row>
18818 <entry role="func_table_entry"><para role="func_signature">
18819 <indexterm>
18820 <primary>array_append</primary>
18821 </indexterm>
18822 <function>array_append</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
18823 <returnvalue>anycompatiblearray</returnvalue>
18824 </para>
18825 <para>
18826 Appends an element to the end of an array (same as
18827 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
18828 operator).
18829 </para>
18830 <para>
18831 <literal>array_append(ARRAY[1,2], 3)</literal>
18832 <returnvalue>{1,2,3}</returnvalue>
18833 </para></entry>
18834 </row>
18836 <row>
18837 <entry role="func_table_entry"><para role="func_signature">
18838 <indexterm>
18839 <primary>array_cat</primary>
18840 </indexterm>
18841 <function>array_cat</function> ( <type>anycompatiblearray</type>, <type>anycompatiblearray</type> )
18842 <returnvalue>anycompatiblearray</returnvalue>
18843 </para>
18844 <para>
18845 Concatenates two arrays (same as
18846 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
18847 operator).
18848 </para>
18849 <para>
18850 <literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal>
18851 <returnvalue>{1,2,3,4,5}</returnvalue>
18852 </para></entry>
18853 </row>
18855 <row>
18856 <entry role="func_table_entry"><para role="func_signature">
18857 <indexterm>
18858 <primary>array_dims</primary>
18859 </indexterm>
18860 <function>array_dims</function> ( <type>anyarray</type> )
18861 <returnvalue>text</returnvalue>
18862 </para>
18863 <para>
18864 Returns a text representation of the array's dimensions.
18865 </para>
18866 <para>
18867 <literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal>
18868 <returnvalue>[1:2][1:3]</returnvalue>
18869 </para></entry>
18870 </row>
18872 <row>
18873 <entry role="func_table_entry"><para role="func_signature">
18874 <indexterm>
18875 <primary>array_fill</primary>
18876 </indexterm>
18877 <function>array_fill</function> ( <type>anyelement</type>, <type>integer[]</type>
18878 <optional>, <type>integer[]</type> </optional> )
18879 <returnvalue>anyarray</returnvalue>
18880 </para>
18881 <para>
18882 Returns an array filled with copies of the given value, having
18883 dimensions of the lengths specified by the second argument.
18884 The optional third argument supplies lower-bound values for each
18885 dimension (which default to all <literal>1</literal>).
18886 </para>
18887 <para>
18888 <literal>array_fill(11, ARRAY[2,3])</literal>
18889 <returnvalue>{{11,11,11},{11,11,11}}</returnvalue>
18890 </para>
18891 <para>
18892 <literal>array_fill(7, ARRAY[3], ARRAY[2])</literal>
18893 <returnvalue>[2:4]={7,7,7}</returnvalue>
18894 </para></entry>
18895 </row>
18897 <row>
18898 <entry role="func_table_entry"><para role="func_signature">
18899 <indexterm>
18900 <primary>array_length</primary>
18901 </indexterm>
18902 <function>array_length</function> ( <type>anyarray</type>, <type>integer</type> )
18903 <returnvalue>integer</returnvalue>
18904 </para>
18905 <para>
18906 Returns the length of the requested array dimension.
18907 (Produces NULL instead of 0 for empty or missing array dimensions.)
18908 </para>
18909 <para>
18910 <literal>array_length(array[1,2,3], 1)</literal>
18911 <returnvalue>3</returnvalue>
18912 </para>
18913 <para>
18914 <literal>array_length(array[]::int[], 1)</literal>
18915 <returnvalue>NULL</returnvalue>
18916 </para>
18917 <para>
18918 <literal>array_length(array['text'], 2)</literal>
18919 <returnvalue>NULL</returnvalue>
18920 </para></entry>
18921 </row>
18923 <row>
18924 <entry role="func_table_entry"><para role="func_signature">
18925 <indexterm>
18926 <primary>array_lower</primary>
18927 </indexterm>
18928 <function>array_lower</function> ( <type>anyarray</type>, <type>integer</type> )
18929 <returnvalue>integer</returnvalue>
18930 </para>
18931 <para>
18932 Returns the lower bound of the requested array dimension.
18933 </para>
18934 <para>
18935 <literal>array_lower('[0:2]={1,2,3}'::integer[], 1)</literal>
18936 <returnvalue>0</returnvalue>
18937 </para></entry>
18938 </row>
18940 <row>
18941 <entry role="func_table_entry"><para role="func_signature">
18942 <indexterm>
18943 <primary>array_ndims</primary>
18944 </indexterm>
18945 <function>array_ndims</function> ( <type>anyarray</type> )
18946 <returnvalue>integer</returnvalue>
18947 </para>
18948 <para>
18949 Returns the number of dimensions of the array.
18950 </para>
18951 <para>
18952 <literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal>
18953 <returnvalue>2</returnvalue>
18954 </para></entry>
18955 </row>
18957 <row>
18958 <entry role="func_table_entry"><para role="func_signature">
18959 <indexterm>
18960 <primary>array_position</primary>
18961 </indexterm>
18962 <function>array_position</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> <optional>, <type>integer</type> </optional> )
18963 <returnvalue>integer</returnvalue>
18964 </para>
18965 <para>
18966 Returns the subscript of the first occurrence of the second argument
18967 in the array, or <literal>NULL</literal> if it's not present.
18968 If the third argument is given, the search begins at that subscript.
18969 The array must be one-dimensional.
18970 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
18971 semantics, so it is possible to search for <literal>NULL</literal>.
18972 </para>
18973 <para>
18974 <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')</literal>
18975 <returnvalue>2</returnvalue>
18976 </para></entry>
18977 </row>
18979 <row>
18980 <entry role="func_table_entry"><para role="func_signature">
18981 <indexterm>
18982 <primary>array_positions</primary>
18983 </indexterm>
18984 <function>array_positions</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
18985 <returnvalue>integer[]</returnvalue>
18986 </para>
18987 <para>
18988 Returns an array of the subscripts of all occurrences of the second
18989 argument in the array given as first argument.
18990 The array must be one-dimensional.
18991 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
18992 semantics, so it is possible to search for <literal>NULL</literal>.
18993 <literal>NULL</literal> is returned only if the array
18994 is <literal>NULL</literal>; if the value is not found in the array, an
18995 empty array is returned.
18996 </para>
18997 <para>
18998 <literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal>
18999 <returnvalue>{1,2,4}</returnvalue>
19000 </para></entry>
19001 </row>
19003 <row>
19004 <entry role="func_table_entry"><para role="func_signature">
19005 <indexterm>
19006 <primary>array_prepend</primary>
19007 </indexterm>
19008 <function>array_prepend</function> ( <type>anycompatible</type>, <type>anycompatiblearray</type> )
19009 <returnvalue>anycompatiblearray</returnvalue>
19010 </para>
19011 <para>
19012 Prepends an element to the beginning of an array (same as
19013 the <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
19014 operator).
19015 </para>
19016 <para>
19017 <literal>array_prepend(1, ARRAY[2,3])</literal>
19018 <returnvalue>{1,2,3}</returnvalue>
19019 </para></entry>
19020 </row>
19022 <row>
19023 <entry role="func_table_entry"><para role="func_signature">
19024 <indexterm>
19025 <primary>array_remove</primary>
19026 </indexterm>
19027 <function>array_remove</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
19028 <returnvalue>anycompatiblearray</returnvalue>
19029 </para>
19030 <para>
19031 Removes all elements equal to the given value from the array.
19032 The array must be one-dimensional.
19033 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
19034 semantics, so it is possible to remove <literal>NULL</literal>s.
19035 </para>
19036 <para>
19037 <literal>array_remove(ARRAY[1,2,3,2], 2)</literal>
19038 <returnvalue>{1,3}</returnvalue>
19039 </para></entry>
19040 </row>
19042 <row>
19043 <entry role="func_table_entry"><para role="func_signature">
19044 <indexterm>
19045 <primary>array_replace</primary>
19046 </indexterm>
19047 <function>array_replace</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type>, <type>anycompatible</type> )
19048 <returnvalue>anycompatiblearray</returnvalue>
19049 </para>
19050 <para>
19051 Replaces each array element equal to the second argument with the
19052 third argument.
19053 </para>
19054 <para>
19055 <literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal>
19056 <returnvalue>{1,2,3,4}</returnvalue>
19057 </para></entry>
19058 </row>
19060 <row>
19061 <entry role="func_table_entry"><para role="func_signature">
19062 <indexterm>
19063 <primary>array_sample</primary>
19064 </indexterm>
19065 <function>array_sample</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
19066 <returnvalue>anyarray</returnvalue>
19067 </para>
19068 <para>
19069 Returns an array of <parameter>n</parameter> items randomly selected
19070 from <parameter>array</parameter>. <parameter>n</parameter> may not
19071 exceed the length of <parameter>array</parameter>'s first dimension.
19072 If <parameter>array</parameter> is multi-dimensional,
19073 an <quote>item</quote> is a slice having a given first subscript.
19074 </para>
19075 <para>
19076 <literal>array_sample(ARRAY[1,2,3,4,5,6], 3)</literal>
19077 <returnvalue>{2,6,1}</returnvalue>
19078 </para>
19079 <para>
19080 <literal>array_sample(ARRAY[[1,2],[3,4],[5,6]], 2)</literal>
19081 <returnvalue>{{5,6},{1,2}}</returnvalue>
19082 </para></entry>
19083 </row>
19085 <row>
19086 <entry role="func_table_entry"><para role="func_signature">
19087 <indexterm>
19088 <primary>array_shuffle</primary>
19089 </indexterm>
19090 <function>array_shuffle</function> ( <type>anyarray</type> )
19091 <returnvalue>anyarray</returnvalue>
19092 </para>
19093 <para>
19094 Randomly shuffles the first dimension of the array.
19095 </para>
19096 <para>
19097 <literal>array_shuffle(ARRAY[[1,2],[3,4],[5,6]])</literal>
19098 <returnvalue>{{5,6},{1,2},{3,4}}</returnvalue>
19099 </para></entry>
19100 </row>
19102 <row>
19103 <entry role="func_table_entry"><para role="func_signature">
19104 <indexterm id="function-array-to-string">
19105 <primary>array_to_string</primary>
19106 </indexterm>
19107 <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> )
19108 <returnvalue>text</returnvalue>
19109 </para>
19110 <para>
19111 Converts each array element to its text representation, and
19112 concatenates those separated by
19113 the <parameter>delimiter</parameter> string.
19114 If <parameter>null_string</parameter> is given and is
19115 not <literal>NULL</literal>, then <literal>NULL</literal> array
19116 entries are represented by that string; otherwise, they are omitted.
19117 See also <link linkend="function-string-to-array"><function>string_to_array</function></link>.
19118 </para>
19119 <para>
19120 <literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal>
19121 <returnvalue>1,2,3,*,5</returnvalue>
19122 </para></entry>
19123 </row>
19125 <row>
19126 <entry role="func_table_entry"><para role="func_signature">
19127 <indexterm>
19128 <primary>array_upper</primary>
19129 </indexterm>
19130 <function>array_upper</function> ( <type>anyarray</type>, <type>integer</type> )
19131 <returnvalue>integer</returnvalue>
19132 </para>
19133 <para>
19134 Returns the upper bound of the requested array dimension.
19135 </para>
19136 <para>
19137 <literal>array_upper(ARRAY[1,8,3,7], 1)</literal>
19138 <returnvalue>4</returnvalue>
19139 </para></entry>
19140 </row>
19142 <row>
19143 <entry role="func_table_entry"><para role="func_signature">
19144 <indexterm>
19145 <primary>cardinality</primary>
19146 </indexterm>
19147 <function>cardinality</function> ( <type>anyarray</type> )
19148 <returnvalue>integer</returnvalue>
19149 </para>
19150 <para>
19151 Returns the total number of elements in the array, or 0 if the array
19152 is empty.
19153 </para>
19154 <para>
19155 <literal>cardinality(ARRAY[[1,2],[3,4]])</literal>
19156 <returnvalue>4</returnvalue>
19157 </para></entry>
19158 </row>
19160 <row>
19161 <entry role="func_table_entry"><para role="func_signature">
19162 <indexterm>
19163 <primary>trim_array</primary>
19164 </indexterm>
19165 <function>trim_array</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
19166 <returnvalue>anyarray</returnvalue>
19167 </para>
19168 <para>
19169 Trims an array by removing the last <parameter>n</parameter> elements.
19170 If the array is multidimensional, only the first dimension is trimmed.
19171 </para>
19172 <para>
19173 <literal>trim_array(ARRAY[1,2,3,4,5,6], 2)</literal>
19174 <returnvalue>{1,2,3,4}</returnvalue>
19175 </para></entry>
19176 </row>
19178 <row>
19179 <entry role="func_table_entry"><para role="func_signature">
19180 <indexterm>
19181 <primary>unnest</primary>
19182 </indexterm>
19183 <function>unnest</function> ( <type>anyarray</type> )
19184 <returnvalue>setof anyelement</returnvalue>
19185 </para>
19186 <para>
19187 Expands an array into a set of rows.
19188 The array's elements are read out in storage order.
19189 </para>
19190 <para>
19191 <literal>unnest(ARRAY[1,2])</literal>
19192 <returnvalue></returnvalue>
19193 <programlisting>
19196 </programlisting>
19197 </para>
19198 <para>
19199 <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])</literal>
19200 <returnvalue></returnvalue>
19201 <programlisting>
19205 quux
19206 </programlisting>
19207 </para></entry>
19208 </row>
19210 <row>
19211 <entry role="func_table_entry"><para role="func_signature">
19212 <function>unnest</function> ( <type>anyarray</type>, <type>anyarray</type> <optional>, ... </optional> )
19213 <returnvalue>setof anyelement, anyelement [, ... ]</returnvalue>
19214 </para>
19215 <para>
19216 Expands multiple arrays (possibly of different data types) into a set of
19217 rows. If the arrays are not all the same length then the shorter ones
19218 are padded with <literal>NULL</literal>s. This form is only allowed
19219 in a query's FROM clause; see <xref linkend="queries-tablefunctions"/>.
19220 </para>
19221 <para>
19222 <literal>select * from unnest(ARRAY[1,2], ARRAY['foo','bar','baz']) as x(a,b)</literal>
19223 <returnvalue></returnvalue>
19224 <programlisting>
19225 a | b
19226 ---+-----
19227 1 | foo
19228 2 | bar
19229 | baz
19230 </programlisting>
19231 </para></entry>
19232 </row>
19233 </tbody>
19234 </tgroup>
19235 </table>
19237 <para>
19238 See also <xref linkend="functions-aggregate"/> about the aggregate
19239 function <function>array_agg</function> for use with arrays.
19240 </para>
19241 </sect1>
19243 <sect1 id="functions-range">
19244 <title>Range/Multirange Functions and Operators</title>
19246 <para>
19247 See <xref linkend="rangetypes"/> for an overview of range types.
19248 </para>
19250 <para>
19251 <xref linkend="range-operators-table"/> shows the specialized operators
19252 available for range types.
19253 <xref linkend="multirange-operators-table"/> shows the specialized operators
19254 available for multirange types.
19255 In addition to those, the usual comparison operators shown in
19256 <xref linkend="functions-comparison-op-table"/> are available for range
19257 and multirange types. The comparison operators order first by the range lower
19258 bounds, and only if those are equal do they compare the upper bounds. The
19259 multirange operators compare each range until one is unequal. This
19260 does not usually result in a useful overall ordering, but the operators are
19261 provided to allow unique indexes to be constructed on ranges.
19262 </para>
19264 <table id="range-operators-table">
19265 <title>Range Operators</title>
19266 <tgroup cols="1">
19267 <thead>
19268 <row>
19269 <entry role="func_table_entry"><para role="func_signature">
19270 Operator
19271 </para>
19272 <para>
19273 Description
19274 </para>
19275 <para>
19276 Example(s)
19277 </para></entry>
19278 </row>
19279 </thead>
19281 <tbody>
19282 <row>
19283 <entry role="func_table_entry"><para role="func_signature">
19284 <type>anyrange</type> <literal>@&gt;</literal> <type>anyrange</type>
19285 <returnvalue>boolean</returnvalue>
19286 </para>
19287 <para>
19288 Does the first range contain the second?
19289 </para>
19290 <para>
19291 <literal>int4range(2,4) @&gt; int4range(2,3)</literal>
19292 <returnvalue>t</returnvalue>
19293 </para></entry>
19294 </row>
19296 <row>
19297 <entry role="func_table_entry"><para role="func_signature">
19298 <type>anyrange</type> <literal>@&gt;</literal> <type>anyelement</type>
19299 <returnvalue>boolean</returnvalue>
19300 </para>
19301 <para>
19302 Does the range contain the element?
19303 </para>
19304 <para>
19305 <literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal>
19306 <returnvalue>t</returnvalue>
19307 </para></entry>
19308 </row>
19310 <row>
19311 <entry role="func_table_entry"><para role="func_signature">
19312 <type>anyrange</type> <literal>&lt;@</literal> <type>anyrange</type>
19313 <returnvalue>boolean</returnvalue>
19314 </para>
19315 <para>
19316 Is the first range contained by the second?
19317 </para>
19318 <para>
19319 <literal>int4range(2,4) &lt;@ int4range(1,7)</literal>
19320 <returnvalue>t</returnvalue>
19321 </para></entry>
19322 </row>
19324 <row>
19325 <entry role="func_table_entry"><para role="func_signature">
19326 <type>anyelement</type> <literal>&lt;@</literal> <type>anyrange</type>
19327 <returnvalue>boolean</returnvalue>
19328 </para>
19329 <para>
19330 Is the element contained in the range?
19331 </para>
19332 <para>
19333 <literal>42 &lt;@ int4range(1,7)</literal>
19334 <returnvalue>f</returnvalue>
19335 </para></entry>
19336 </row>
19338 <row>
19339 <entry role="func_table_entry"><para role="func_signature">
19340 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
19341 <returnvalue>boolean</returnvalue>
19342 </para>
19343 <para>
19344 Do the ranges overlap, that is, have any elements in common?
19345 </para>
19346 <para>
19347 <literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal>
19348 <returnvalue>t</returnvalue>
19349 </para></entry>
19350 </row>
19352 <row>
19353 <entry role="func_table_entry"><para role="func_signature">
19354 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
19355 <returnvalue>boolean</returnvalue>
19356 </para>
19357 <para>
19358 Is the first range strictly left of the second?
19359 </para>
19360 <para>
19361 <literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal>
19362 <returnvalue>t</returnvalue>
19363 </para></entry>
19364 </row>
19366 <row>
19367 <entry role="func_table_entry"><para role="func_signature">
19368 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
19369 <returnvalue>boolean</returnvalue>
19370 </para>
19371 <para>
19372 Is the first range strictly right of the second?
19373 </para>
19374 <para>
19375 <literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal>
19376 <returnvalue>t</returnvalue>
19377 </para></entry>
19378 </row>
19380 <row>
19381 <entry role="func_table_entry"><para role="func_signature">
19382 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
19383 <returnvalue>boolean</returnvalue>
19384 </para>
19385 <para>
19386 Does the first range not extend to the right of the second?
19387 </para>
19388 <para>
19389 <literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal>
19390 <returnvalue>t</returnvalue>
19391 </para></entry>
19392 </row>
19394 <row>
19395 <entry role="func_table_entry"><para role="func_signature">
19396 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
19397 <returnvalue>boolean</returnvalue>
19398 </para>
19399 <para>
19400 Does the first range not extend to the left of the second?
19401 </para>
19402 <para>
19403 <literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal>
19404 <returnvalue>t</returnvalue>
19405 </para></entry>
19406 </row>
19408 <row>
19409 <entry role="func_table_entry"><para role="func_signature">
19410 <type>anyrange</type> <literal>-|-</literal> <type>anyrange</type>
19411 <returnvalue>boolean</returnvalue>
19412 </para>
19413 <para>
19414 Are the ranges adjacent?
19415 </para>
19416 <para>
19417 <literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal>
19418 <returnvalue>t</returnvalue>
19419 </para></entry>
19420 </row>
19422 <row>
19423 <entry role="func_table_entry"><para role="func_signature">
19424 <type>anyrange</type> <literal>+</literal> <type>anyrange</type>
19425 <returnvalue>anyrange</returnvalue>
19426 </para>
19427 <para>
19428 Computes the union of the ranges. The ranges must overlap or be
19429 adjacent, so that the union is a single range (but
19430 see <function>range_merge()</function>).
19431 </para>
19432 <para>
19433 <literal>numrange(5,15) + numrange(10,20)</literal>
19434 <returnvalue>[5,20)</returnvalue>
19435 </para></entry>
19436 </row>
19438 <row>
19439 <entry role="func_table_entry"><para role="func_signature">
19440 <type>anyrange</type> <literal>*</literal> <type>anyrange</type>
19441 <returnvalue>anyrange</returnvalue>
19442 </para>
19443 <para>
19444 Computes the intersection of the ranges.
19445 </para>
19446 <para>
19447 <literal>int8range(5,15) * int8range(10,20)</literal>
19448 <returnvalue>[10,15)</returnvalue>
19449 </para></entry>
19450 </row>
19452 <row>
19453 <entry role="func_table_entry"><para role="func_signature">
19454 <type>anyrange</type> <literal>-</literal> <type>anyrange</type>
19455 <returnvalue>anyrange</returnvalue>
19456 </para>
19457 <para>
19458 Computes the difference of the ranges. The second range must not be
19459 contained in the first in such a way that the difference would not be
19460 a single range.
19461 </para>
19462 <para>
19463 <literal>int8range(5,15) - int8range(10,20)</literal>
19464 <returnvalue>[5,10)</returnvalue>
19465 </para></entry>
19466 </row>
19467 </tbody>
19468 </tgroup>
19469 </table>
19471 <table id="multirange-operators-table">
19472 <title>Multirange Operators</title>
19473 <tgroup cols="1">
19474 <thead>
19475 <row>
19476 <entry role="func_table_entry"><para role="func_signature">
19477 Operator
19478 </para>
19479 <para>
19480 Description
19481 </para>
19482 <para>
19483 Example(s)
19484 </para></entry>
19485 </row>
19486 </thead>
19488 <tbody>
19489 <row>
19490 <entry role="func_table_entry"><para role="func_signature">
19491 <type>anymultirange</type> <literal>@&gt;</literal> <type>anymultirange</type>
19492 <returnvalue>boolean</returnvalue>
19493 </para>
19494 <para>
19495 Does the first multirange contain the second?
19496 </para>
19497 <para>
19498 <literal>'{[2,4)}'::int4multirange @&gt; '{[2,3)}'::int4multirange</literal>
19499 <returnvalue>t</returnvalue>
19500 </para></entry>
19501 </row>
19503 <row>
19504 <entry role="func_table_entry"><para role="func_signature">
19505 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyrange</type>
19506 <returnvalue>boolean</returnvalue>
19507 </para>
19508 <para>
19509 Does the multirange contain the range?
19510 </para>
19511 <para>
19512 <literal>'{[2,4)}'::int4multirange @&gt; int4range(2,3)</literal>
19513 <returnvalue>t</returnvalue>
19514 </para></entry>
19515 </row>
19517 <row>
19518 <entry role="func_table_entry"><para role="func_signature">
19519 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyelement</type>
19520 <returnvalue>boolean</returnvalue>
19521 </para>
19522 <para>
19523 Does the multirange contain the element?
19524 </para>
19525 <para>
19526 <literal>'{[2011-01-01,2011-03-01)}'::tsmultirange @&gt; '2011-01-10'::timestamp</literal>
19527 <returnvalue>t</returnvalue>
19528 </para></entry>
19529 </row>
19531 <row>
19532 <entry role="func_table_entry"><para role="func_signature">
19533 <type>anyrange</type> <literal>@&gt;</literal> <type>anymultirange</type>
19534 <returnvalue>boolean</returnvalue>
19535 </para>
19536 <para>
19537 Does the range contain the multirange?
19538 </para>
19539 <para>
19540 <literal>'[2,4)'::int4range @&gt; '{[2,3)}'::int4multirange</literal>
19541 <returnvalue>t</returnvalue>
19542 </para></entry>
19543 </row>
19545 <row>
19546 <entry role="func_table_entry"><para role="func_signature">
19547 <type>anymultirange</type> <literal>&lt;@</literal> <type>anymultirange</type>
19548 <returnvalue>boolean</returnvalue>
19549 </para>
19550 <para>
19551 Is the first multirange contained by the second?
19552 </para>
19553 <para>
19554 <literal>'{[2,4)}'::int4multirange &lt;@ '{[1,7)}'::int4multirange</literal>
19555 <returnvalue>t</returnvalue>
19556 </para></entry>
19557 </row>
19559 <row>
19560 <entry role="func_table_entry"><para role="func_signature">
19561 <type>anymultirange</type> <literal>&lt;@</literal> <type>anyrange</type>
19562 <returnvalue>boolean</returnvalue>
19563 </para>
19564 <para>
19565 Is the multirange contained by the range?
19566 </para>
19567 <para>
19568 <literal>'{[2,4)}'::int4multirange &lt;@ int4range(1,7)</literal>
19569 <returnvalue>t</returnvalue>
19570 </para></entry>
19571 </row>
19573 <row>
19574 <entry role="func_table_entry"><para role="func_signature">
19575 <type>anyrange</type> <literal>&lt;@</literal> <type>anymultirange</type>
19576 <returnvalue>boolean</returnvalue>
19577 </para>
19578 <para>
19579 Is the range contained by the multirange?
19580 </para>
19581 <para>
19582 <literal>int4range(2,4) &lt;@ '{[1,7)}'::int4multirange</literal>
19583 <returnvalue>t</returnvalue>
19584 </para></entry>
19585 </row>
19587 <row>
19588 <entry role="func_table_entry"><para role="func_signature">
19589 <type>anyelement</type> <literal>&lt;@</literal> <type>anymultirange</type>
19590 <returnvalue>boolean</returnvalue>
19591 </para>
19592 <para>
19593 Is the element contained by the multirange?
19594 </para>
19595 <para>
19596 <literal>4 &lt;@ '{[1,7)}'::int4multirange</literal>
19597 <returnvalue>t</returnvalue>
19598 </para></entry>
19599 </row>
19601 <row>
19602 <entry role="func_table_entry"><para role="func_signature">
19603 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
19604 <returnvalue>boolean</returnvalue>
19605 </para>
19606 <para>
19607 Do the multiranges overlap, that is, have any elements in common?
19608 </para>
19609 <para>
19610 <literal>'{[3,7)}'::int8multirange &amp;&amp; '{[4,12)}'::int8multirange</literal>
19611 <returnvalue>t</returnvalue>
19612 </para></entry>
19613 </row>
19615 <row>
19616 <entry role="func_table_entry"><para role="func_signature">
19617 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
19618 <returnvalue>boolean</returnvalue>
19619 </para>
19620 <para>
19621 Does the multirange overlap the range?
19622 </para>
19623 <para>
19624 <literal>'{[3,7)}'::int8multirange &amp;&amp; int8range(4,12)</literal>
19625 <returnvalue>t</returnvalue>
19626 </para></entry>
19627 </row>
19629 <row>
19630 <entry role="func_table_entry"><para role="func_signature">
19631 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
19632 <returnvalue>boolean</returnvalue>
19633 </para>
19634 <para>
19635 Does the range overlap the multirange?
19636 </para>
19637 <para>
19638 <literal>int8range(3,7) &amp;&amp; '{[4,12)}'::int8multirange</literal>
19639 <returnvalue>t</returnvalue>
19640 </para></entry>
19641 </row>
19643 <row>
19644 <entry role="func_table_entry"><para role="func_signature">
19645 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
19646 <returnvalue>boolean</returnvalue>
19647 </para>
19648 <para>
19649 Is the first multirange strictly left of the second?
19650 </para>
19651 <para>
19652 <literal>'{[1,10)}'::int8multirange &lt;&lt; '{[100,110)}'::int8multirange</literal>
19653 <returnvalue>t</returnvalue>
19654 </para></entry>
19655 </row>
19657 <row>
19658 <entry role="func_table_entry"><para role="func_signature">
19659 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
19660 <returnvalue>boolean</returnvalue>
19661 </para>
19662 <para>
19663 Is the multirange strictly left of the range?
19664 </para>
19665 <para>
19666 <literal>'{[1,10)}'::int8multirange &lt;&lt; int8range(100,110)</literal>
19667 <returnvalue>t</returnvalue>
19668 </para></entry>
19669 </row>
19671 <row>
19672 <entry role="func_table_entry"><para role="func_signature">
19673 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
19674 <returnvalue>boolean</returnvalue>
19675 </para>
19676 <para>
19677 Is the range strictly left of the multirange?
19678 </para>
19679 <para>
19680 <literal>int8range(1,10) &lt;&lt; '{[100,110)}'::int8multirange</literal>
19681 <returnvalue>t</returnvalue>
19682 </para></entry>
19683 </row>
19685 <row>
19686 <entry role="func_table_entry"><para role="func_signature">
19687 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
19688 <returnvalue>boolean</returnvalue>
19689 </para>
19690 <para>
19691 Is the first multirange strictly right of the second?
19692 </para>
19693 <para>
19694 <literal>'{[50,60)}'::int8multirange &gt;&gt; '{[20,30)}'::int8multirange</literal>
19695 <returnvalue>t</returnvalue>
19696 </para></entry>
19697 </row>
19699 <row>
19700 <entry role="func_table_entry"><para role="func_signature">
19701 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
19702 <returnvalue>boolean</returnvalue>
19703 </para>
19704 <para>
19705 Is the multirange strictly right of the range?
19706 </para>
19707 <para>
19708 <literal>'{[50,60)}'::int8multirange &gt;&gt; int8range(20,30)</literal>
19709 <returnvalue>t</returnvalue>
19710 </para></entry>
19711 </row>
19713 <row>
19714 <entry role="func_table_entry"><para role="func_signature">
19715 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
19716 <returnvalue>boolean</returnvalue>
19717 </para>
19718 <para>
19719 Is the range strictly right of the multirange?
19720 </para>
19721 <para>
19722 <literal>int8range(50,60) &gt;&gt; '{[20,30)}'::int8multirange</literal>
19723 <returnvalue>t</returnvalue>
19724 </para></entry>
19725 </row>
19727 <row>
19728 <entry role="func_table_entry"><para role="func_signature">
19729 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
19730 <returnvalue>boolean</returnvalue>
19731 </para>
19732 <para>
19733 Does the first multirange not extend to the right of the second?
19734 </para>
19735 <para>
19736 <literal>'{[1,20)}'::int8multirange &amp;&lt; '{[18,20)}'::int8multirange</literal>
19737 <returnvalue>t</returnvalue>
19738 </para></entry>
19739 </row>
19741 <row>
19742 <entry role="func_table_entry"><para role="func_signature">
19743 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
19744 <returnvalue>boolean</returnvalue>
19745 </para>
19746 <para>
19747 Does the multirange not extend to the right of the range?
19748 </para>
19749 <para>
19750 <literal>'{[1,20)}'::int8multirange &amp;&lt; int8range(18,20)</literal>
19751 <returnvalue>t</returnvalue>
19752 </para></entry>
19753 </row>
19755 <row>
19756 <entry role="func_table_entry"><para role="func_signature">
19757 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
19758 <returnvalue>boolean</returnvalue>
19759 </para>
19760 <para>
19761 Does the range not extend to the right of the multirange?
19762 </para>
19763 <para>
19764 <literal>int8range(1,20) &amp;&lt; '{[18,20)}'::int8multirange</literal>
19765 <returnvalue>t</returnvalue>
19766 </para></entry>
19767 </row>
19769 <row>
19770 <entry role="func_table_entry"><para role="func_signature">
19771 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
19772 <returnvalue>boolean</returnvalue>
19773 </para>
19774 <para>
19775 Does the first multirange not extend to the left of the second?
19776 </para>
19777 <para>
19778 <literal>'{[7,20)}'::int8multirange &amp;&gt; '{[5,10)}'::int8multirange</literal>
19779 <returnvalue>t</returnvalue>
19780 </para></entry>
19781 </row>
19783 <row>
19784 <entry role="func_table_entry"><para role="func_signature">
19785 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
19786 <returnvalue>boolean</returnvalue>
19787 </para>
19788 <para>
19789 Does the multirange not extend to the left of the range?
19790 </para>
19791 <para>
19792 <literal>'{[7,20)}'::int8multirange &amp;&gt; int8range(5,10)</literal>
19793 <returnvalue>t</returnvalue>
19794 </para></entry>
19795 </row>
19797 <row>
19798 <entry role="func_table_entry"><para role="func_signature">
19799 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
19800 <returnvalue>boolean</returnvalue>
19801 </para>
19802 <para>
19803 Does the range not extend to the left of the multirange?
19804 </para>
19805 <para>
19806 <literal>int8range(7,20) &amp;&gt; '{[5,10)}'::int8multirange</literal>
19807 <returnvalue>t</returnvalue>
19808 </para></entry>
19809 </row>
19811 <row>
19812 <entry role="func_table_entry"><para role="func_signature">
19813 <type>anymultirange</type> <literal>-|-</literal> <type>anymultirange</type>
19814 <returnvalue>boolean</returnvalue>
19815 </para>
19816 <para>
19817 Are the multiranges adjacent?
19818 </para>
19819 <para>
19820 <literal>'{[1.1,2.2)}'::nummultirange -|- '{[2.2,3.3)}'::nummultirange</literal>
19821 <returnvalue>t</returnvalue>
19822 </para></entry>
19823 </row>
19825 <row>
19826 <entry role="func_table_entry"><para role="func_signature">
19827 <type>anymultirange</type> <literal>-|-</literal> <type>anyrange</type>
19828 <returnvalue>boolean</returnvalue>
19829 </para>
19830 <para>
19831 Is the multirange adjacent to the range?
19832 </para>
19833 <para>
19834 <literal>'{[1.1,2.2)}'::nummultirange -|- numrange(2.2,3.3)</literal>
19835 <returnvalue>t</returnvalue>
19836 </para></entry>
19837 </row>
19839 <row>
19840 <entry role="func_table_entry"><para role="func_signature">
19841 <type>anyrange</type> <literal>-|-</literal> <type>anymultirange</type>
19842 <returnvalue>boolean</returnvalue>
19843 </para>
19844 <para>
19845 Is the range adjacent to the multirange?
19846 </para>
19847 <para>
19848 <literal>numrange(1.1,2.2) -|- '{[2.2,3.3)}'::nummultirange</literal>
19849 <returnvalue>t</returnvalue>
19850 </para></entry>
19851 </row>
19853 <row>
19854 <entry role="func_table_entry"><para role="func_signature">
19855 <type>anymultirange</type> <literal>+</literal> <type>anymultirange</type>
19856 <returnvalue>anymultirange</returnvalue>
19857 </para>
19858 <para>
19859 Computes the union of the multiranges. The multiranges need not overlap
19860 or be adjacent.
19861 </para>
19862 <para>
19863 <literal>'{[5,10)}'::nummultirange + '{[15,20)}'::nummultirange</literal>
19864 <returnvalue>{[5,10), [15,20)}</returnvalue>
19865 </para></entry>
19866 </row>
19868 <row>
19869 <entry role="func_table_entry"><para role="func_signature">
19870 <type>anymultirange</type> <literal>*</literal> <type>anymultirange</type>
19871 <returnvalue>anymultirange</returnvalue>
19872 </para>
19873 <para>
19874 Computes the intersection of the multiranges.
19875 </para>
19876 <para>
19877 <literal>'{[5,15)}'::int8multirange * '{[10,20)}'::int8multirange</literal>
19878 <returnvalue>{[10,15)}</returnvalue>
19879 </para></entry>
19880 </row>
19882 <row>
19883 <entry role="func_table_entry"><para role="func_signature">
19884 <type>anymultirange</type> <literal>-</literal> <type>anymultirange</type>
19885 <returnvalue>anymultirange</returnvalue>
19886 </para>
19887 <para>
19888 Computes the difference of the multiranges.
19889 </para>
19890 <para>
19891 <literal>'{[5,20)}'::int8multirange - '{[10,15)}'::int8multirange</literal>
19892 <returnvalue>{[5,10), [15,20)}</returnvalue>
19893 </para></entry>
19894 </row>
19895 </tbody>
19896 </tgroup>
19897 </table>
19899 <para>
19900 The left-of/right-of/adjacent operators always return false when an empty
19901 range or multirange is involved; that is, an empty range is not considered to
19902 be either before or after any other range.
19903 </para>
19905 <para>
19906 Elsewhere empty ranges and multiranges are treated as the additive identity:
19907 anything unioned with an empty value is itself. Anything minus an empty
19908 value is itself. An empty multirange has exactly the same points as an empty
19909 range. Every range contains the empty range. Every multirange contains as many
19910 empty ranges as you like.
19911 </para>
19913 <para>
19914 The range union and difference operators will fail if the resulting range would
19915 need to contain two disjoint sub-ranges, as such a range cannot be
19916 represented. There are separate operators for union and difference that take
19917 multirange parameters and return a multirange, and they do not fail even if
19918 their arguments are disjoint. So if you need a union or difference operation
19919 for ranges that may be disjoint, you can avoid errors by first casting your
19920 ranges to multiranges.
19921 </para>
19923 <para>
19924 <xref linkend="range-functions-table"/> shows the functions
19925 available for use with range types.
19926 <xref linkend="multirange-functions-table"/> shows the functions
19927 available for use with multirange types.
19928 </para>
19930 <table id="range-functions-table">
19931 <title>Range Functions</title>
19932 <tgroup cols="1">
19933 <thead>
19934 <row>
19935 <entry role="func_table_entry"><para role="func_signature">
19936 Function
19937 </para>
19938 <para>
19939 Description
19940 </para>
19941 <para>
19942 Example(s)
19943 </para></entry>
19944 </row>
19945 </thead>
19947 <tbody>
19948 <row>
19949 <entry role="func_table_entry"><para role="func_signature">
19950 <indexterm>
19951 <primary>lower</primary>
19952 </indexterm>
19953 <function>lower</function> ( <type>anyrange</type> )
19954 <returnvalue>anyelement</returnvalue>
19955 </para>
19956 <para>
19957 Extracts the lower bound of the range (<literal>NULL</literal> if the
19958 range is empty or has no lower bound).
19959 </para>
19960 <para>
19961 <literal>lower(numrange(1.1,2.2))</literal>
19962 <returnvalue>1.1</returnvalue>
19963 </para></entry>
19964 </row>
19966 <row>
19967 <entry role="func_table_entry"><para role="func_signature">
19968 <indexterm>
19969 <primary>upper</primary>
19970 </indexterm>
19971 <function>upper</function> ( <type>anyrange</type> )
19972 <returnvalue>anyelement</returnvalue>
19973 </para>
19974 <para>
19975 Extracts the upper bound of the range (<literal>NULL</literal> if the
19976 range is empty or has no upper bound).
19977 </para>
19978 <para>
19979 <literal>upper(numrange(1.1,2.2))</literal>
19980 <returnvalue>2.2</returnvalue>
19981 </para></entry>
19982 </row>
19984 <row>
19985 <entry role="func_table_entry"><para role="func_signature">
19986 <indexterm>
19987 <primary>isempty</primary>
19988 </indexterm>
19989 <function>isempty</function> ( <type>anyrange</type> )
19990 <returnvalue>boolean</returnvalue>
19991 </para>
19992 <para>
19993 Is the range empty?
19994 </para>
19995 <para>
19996 <literal>isempty(numrange(1.1,2.2))</literal>
19997 <returnvalue>f</returnvalue>
19998 </para></entry>
19999 </row>
20001 <row>
20002 <entry role="func_table_entry"><para role="func_signature">
20003 <indexterm>
20004 <primary>lower_inc</primary>
20005 </indexterm>
20006 <function>lower_inc</function> ( <type>anyrange</type> )
20007 <returnvalue>boolean</returnvalue>
20008 </para>
20009 <para>
20010 Is the range's lower bound inclusive?
20011 </para>
20012 <para>
20013 <literal>lower_inc(numrange(1.1,2.2))</literal>
20014 <returnvalue>t</returnvalue>
20015 </para></entry>
20016 </row>
20018 <row>
20019 <entry role="func_table_entry"><para role="func_signature">
20020 <indexterm>
20021 <primary>upper_inc</primary>
20022 </indexterm>
20023 <function>upper_inc</function> ( <type>anyrange</type> )
20024 <returnvalue>boolean</returnvalue>
20025 </para>
20026 <para>
20027 Is the range's upper bound inclusive?
20028 </para>
20029 <para>
20030 <literal>upper_inc(numrange(1.1,2.2))</literal>
20031 <returnvalue>f</returnvalue>
20032 </para></entry>
20033 </row>
20035 <row>
20036 <entry role="func_table_entry"><para role="func_signature">
20037 <indexterm>
20038 <primary>lower_inf</primary>
20039 </indexterm>
20040 <function>lower_inf</function> ( <type>anyrange</type> )
20041 <returnvalue>boolean</returnvalue>
20042 </para>
20043 <para>
20044 Does the range have no lower bound? (A lower bound of
20045 <literal>-Infinity</literal> returns false.)
20046 </para>
20047 <para>
20048 <literal>lower_inf('(,)'::daterange)</literal>
20049 <returnvalue>t</returnvalue>
20050 </para></entry>
20051 </row>
20053 <row>
20054 <entry role="func_table_entry"><para role="func_signature">
20055 <indexterm>
20056 <primary>upper_inf</primary>
20057 </indexterm>
20058 <function>upper_inf</function> ( <type>anyrange</type> )
20059 <returnvalue>boolean</returnvalue>
20060 </para>
20061 <para>
20062 Does the range have no upper bound? (An upper bound of
20063 <literal>Infinity</literal> returns false.)
20064 </para>
20065 <para>
20066 <literal>upper_inf('(,)'::daterange)</literal>
20067 <returnvalue>t</returnvalue>
20068 </para></entry>
20069 </row>
20071 <row>
20072 <entry role="func_table_entry"><para role="func_signature">
20073 <indexterm>
20074 <primary>range_merge</primary>
20075 </indexterm>
20076 <function>range_merge</function> ( <type>anyrange</type>, <type>anyrange</type> )
20077 <returnvalue>anyrange</returnvalue>
20078 </para>
20079 <para>
20080 Computes the smallest range that includes both of the given ranges.
20081 </para>
20082 <para>
20083 <literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal>
20084 <returnvalue>[1,4)</returnvalue>
20085 </para></entry>
20086 </row>
20087 </tbody>
20088 </tgroup>
20089 </table>
20091 <table id="multirange-functions-table">
20092 <title>Multirange Functions</title>
20093 <tgroup cols="1">
20094 <thead>
20095 <row>
20096 <entry role="func_table_entry"><para role="func_signature">
20097 Function
20098 </para>
20099 <para>
20100 Description
20101 </para>
20102 <para>
20103 Example(s)
20104 </para></entry>
20105 </row>
20106 </thead>
20107 <tbody>
20108 <row>
20109 <entry role="func_table_entry"><para role="func_signature">
20110 <indexterm>
20111 <primary>lower</primary>
20112 </indexterm>
20113 <function>lower</function> ( <type>anymultirange</type> )
20114 <returnvalue>anyelement</returnvalue>
20115 </para>
20116 <para>
20117 Extracts the lower bound of the multirange (<literal>NULL</literal> if the
20118 multirange is empty has no lower bound).
20119 </para>
20120 <para>
20121 <literal>lower('{[1.1,2.2)}'::nummultirange)</literal>
20122 <returnvalue>1.1</returnvalue>
20123 </para></entry>
20124 </row>
20126 <row>
20127 <entry role="func_table_entry"><para role="func_signature">
20128 <indexterm>
20129 <primary>upper</primary>
20130 </indexterm>
20131 <function>upper</function> ( <type>anymultirange</type> )
20132 <returnvalue>anyelement</returnvalue>
20133 </para>
20134 <para>
20135 Extracts the upper bound of the multirange (<literal>NULL</literal> if the
20136 multirange is empty or has no upper bound).
20137 </para>
20138 <para>
20139 <literal>upper('{[1.1,2.2)}'::nummultirange)</literal>
20140 <returnvalue>2.2</returnvalue>
20141 </para></entry>
20142 </row>
20144 <row>
20145 <entry role="func_table_entry"><para role="func_signature">
20146 <indexterm>
20147 <primary>isempty</primary>
20148 </indexterm>
20149 <function>isempty</function> ( <type>anymultirange</type> )
20150 <returnvalue>boolean</returnvalue>
20151 </para>
20152 <para>
20153 Is the multirange empty?
20154 </para>
20155 <para>
20156 <literal>isempty('{[1.1,2.2)}'::nummultirange)</literal>
20157 <returnvalue>f</returnvalue>
20158 </para></entry>
20159 </row>
20161 <row>
20162 <entry role="func_table_entry"><para role="func_signature">
20163 <indexterm>
20164 <primary>lower_inc</primary>
20165 </indexterm>
20166 <function>lower_inc</function> ( <type>anymultirange</type> )
20167 <returnvalue>boolean</returnvalue>
20168 </para>
20169 <para>
20170 Is the multirange's lower bound inclusive?
20171 </para>
20172 <para>
20173 <literal>lower_inc('{[1.1,2.2)}'::nummultirange)</literal>
20174 <returnvalue>t</returnvalue>
20175 </para></entry>
20176 </row>
20178 <row>
20179 <entry role="func_table_entry"><para role="func_signature">
20180 <indexterm>
20181 <primary>upper_inc</primary>
20182 </indexterm>
20183 <function>upper_inc</function> ( <type>anymultirange</type> )
20184 <returnvalue>boolean</returnvalue>
20185 </para>
20186 <para>
20187 Is the multirange's upper bound inclusive?
20188 </para>
20189 <para>
20190 <literal>upper_inc('{[1.1,2.2)}'::nummultirange)</literal>
20191 <returnvalue>f</returnvalue>
20192 </para></entry>
20193 </row>
20195 <row>
20196 <entry role="func_table_entry"><para role="func_signature">
20197 <indexterm>
20198 <primary>lower_inf</primary>
20199 </indexterm>
20200 <function>lower_inf</function> ( <type>anymultirange</type> )
20201 <returnvalue>boolean</returnvalue>
20202 </para>
20203 <para>
20204 Does the multirange have no lower bound? (A lower bound of
20205 <literal>-Infinity</literal> returns false.)
20206 </para>
20207 <para>
20208 <literal>lower_inf('{(,)}'::datemultirange)</literal>
20209 <returnvalue>t</returnvalue>
20210 </para></entry>
20211 </row>
20213 <row>
20214 <entry role="func_table_entry"><para role="func_signature">
20215 <indexterm>
20216 <primary>upper_inf</primary>
20217 </indexterm>
20218 <function>upper_inf</function> ( <type>anymultirange</type> )
20219 <returnvalue>boolean</returnvalue>
20220 </para>
20221 <para>
20222 Does the multirange have no upper bound? (An upper bound of
20223 <literal>Infinity</literal> returns false.)
20224 </para>
20225 <para>
20226 <literal>upper_inf('{(,)}'::datemultirange)</literal>
20227 <returnvalue>t</returnvalue>
20228 </para></entry>
20229 </row>
20231 <row>
20232 <entry role="func_table_entry"><para role="func_signature">
20233 <indexterm>
20234 <primary>range_merge</primary>
20235 </indexterm>
20236 <function>range_merge</function> ( <type>anymultirange</type> )
20237 <returnvalue>anyrange</returnvalue>
20238 </para>
20239 <para>
20240 Computes the smallest range that includes the entire multirange.
20241 </para>
20242 <para>
20243 <literal>range_merge('{[1,2), [3,4)}'::int4multirange)</literal>
20244 <returnvalue>[1,4)</returnvalue>
20245 </para></entry>
20246 </row>
20248 <row>
20249 <entry role="func_table_entry"><para role="func_signature">
20250 <indexterm>
20251 <primary>multirange (function)</primary>
20252 </indexterm>
20253 <function>multirange</function> ( <type>anyrange</type> )
20254 <returnvalue>anymultirange</returnvalue>
20255 </para>
20256 <para>
20257 Returns a multirange containing just the given range.
20258 </para>
20259 <para>
20260 <literal>multirange('[1,2)'::int4range)</literal>
20261 <returnvalue>{[1,2)}</returnvalue>
20262 </para></entry>
20263 </row>
20265 <row>
20266 <entry role="func_table_entry"><para role="func_signature">
20267 <indexterm>
20268 <primary>unnest</primary>
20269 <secondary>for multirange</secondary>
20270 </indexterm>
20271 <function>unnest</function> ( <type>anymultirange</type> )
20272 <returnvalue>setof anyrange</returnvalue>
20273 </para>
20274 <para>
20275 Expands a multirange into a set of ranges in ascending order.
20276 </para>
20277 <para>
20278 <literal>unnest('{[1,2), [3,4)}'::int4multirange)</literal>
20279 <returnvalue></returnvalue>
20280 <programlisting>
20281 [1,2)
20282 [3,4)
20283 </programlisting>
20284 </para></entry>
20285 </row>
20286 </tbody>
20287 </tgroup>
20288 </table>
20290 <para>
20291 The <function>lower_inc</function>, <function>upper_inc</function>,
20292 <function>lower_inf</function>, and <function>upper_inf</function>
20293 functions all return false for an empty range or multirange.
20294 </para>
20295 </sect1>
20297 <sect1 id="functions-aggregate">
20298 <title>Aggregate Functions</title>
20300 <indexterm zone="functions-aggregate">
20301 <primary>aggregate function</primary>
20302 <secondary>built-in</secondary>
20303 </indexterm>
20305 <para>
20306 <firstterm>Aggregate functions</firstterm> compute a single result
20307 from a set of input values. The built-in general-purpose aggregate
20308 functions are listed in <xref linkend="functions-aggregate-table"/>
20309 while statistical aggregates are in <xref
20310 linkend="functions-aggregate-statistics-table"/>.
20311 The built-in within-group ordered-set aggregate functions
20312 are listed in <xref linkend="functions-orderedset-table"/>
20313 while the built-in within-group hypothetical-set ones are in <xref
20314 linkend="functions-hypothetical-table"/>. Grouping operations,
20315 which are closely related to aggregate functions, are listed in
20316 <xref linkend="functions-grouping-table"/>.
20317 The special syntax considerations for aggregate
20318 functions are explained in <xref linkend="syntax-aggregates"/>.
20319 Consult <xref linkend="tutorial-agg"/> for additional introductory
20320 information.
20321 </para>
20323 <para>
20324 Aggregate functions that support <firstterm>Partial Mode</firstterm>
20325 are eligible to participate in various optimizations, such as parallel
20326 aggregation.
20327 </para>
20329 <para>
20330 While all aggregates below accept an optional
20331 <literal>ORDER BY</literal> clause (as outlined in <xref
20332 linkend="syntax-aggregates"/>), the clause has only been added to
20333 aggregates whose output is affected by ordering.
20334 </para>
20336 <table id="functions-aggregate-table">
20337 <title>General-Purpose Aggregate Functions</title>
20338 <tgroup cols="2">
20339 <colspec colname="col1" colwidth="10*"/>
20340 <colspec colname="col2" colwidth="1*"/>
20341 <thead>
20342 <row>
20343 <entry role="func_table_entry"><para role="func_signature">
20344 Function
20345 </para>
20346 <para>
20347 Description
20348 </para></entry>
20349 <entry>Partial Mode</entry>
20350 </row>
20351 </thead>
20353 <tbody>
20354 <row>
20355 <entry role="func_table_entry"><para role="func_signature">
20356 <indexterm>
20357 <primary>any_value</primary>
20358 </indexterm>
20359 <function>any_value</function> ( <type>anyelement</type> )
20360 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
20361 </para>
20362 <para>
20363 Returns an arbitrary value from the non-null input values.
20364 </para></entry>
20365 <entry>Yes</entry>
20366 </row>
20368 <row>
20369 <entry role="func_table_entry"><para role="func_signature">
20370 <indexterm>
20371 <primary>array_agg</primary>
20372 </indexterm>
20373 <function>array_agg</function> ( <type>anynonarray</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20374 <returnvalue>anyarray</returnvalue>
20375 </para>
20376 <para>
20377 Collects all the input values, including nulls, into an array.
20378 </para></entry>
20379 <entry>Yes</entry>
20380 </row>
20382 <row>
20383 <entry role="func_table_entry"><para role="func_signature">
20384 <function>array_agg</function> ( <type>anyarray</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20385 <returnvalue>anyarray</returnvalue>
20386 </para>
20387 <para>
20388 Concatenates all the input arrays into an array of one higher
20389 dimension. (The inputs must all have the same dimensionality, and
20390 cannot be empty or null.)
20391 </para></entry>
20392 <entry>Yes</entry>
20393 </row>
20395 <row>
20396 <entry role="func_table_entry"><para role="func_signature">
20397 <indexterm>
20398 <primary>average</primary>
20399 </indexterm>
20400 <indexterm>
20401 <primary>avg</primary>
20402 </indexterm>
20403 <function>avg</function> ( <type>smallint</type> )
20404 <returnvalue>numeric</returnvalue>
20405 </para>
20406 <para role="func_signature">
20407 <function>avg</function> ( <type>integer</type> )
20408 <returnvalue>numeric</returnvalue>
20409 </para>
20410 <para role="func_signature">
20411 <function>avg</function> ( <type>bigint</type> )
20412 <returnvalue>numeric</returnvalue>
20413 </para>
20414 <para role="func_signature">
20415 <function>avg</function> ( <type>numeric</type> )
20416 <returnvalue>numeric</returnvalue>
20417 </para>
20418 <para role="func_signature">
20419 <function>avg</function> ( <type>real</type> )
20420 <returnvalue>double precision</returnvalue>
20421 </para>
20422 <para role="func_signature">
20423 <function>avg</function> ( <type>double precision</type> )
20424 <returnvalue>double precision</returnvalue>
20425 </para>
20426 <para role="func_signature">
20427 <function>avg</function> ( <type>interval</type> )
20428 <returnvalue>interval</returnvalue>
20429 </para>
20430 <para>
20431 Computes the average (arithmetic mean) of all the non-null input
20432 values.
20433 </para></entry>
20434 <entry>Yes</entry>
20435 </row>
20437 <row>
20438 <entry role="func_table_entry"><para role="func_signature">
20439 <indexterm>
20440 <primary>bit_and</primary>
20441 </indexterm>
20442 <function>bit_and</function> ( <type>smallint</type> )
20443 <returnvalue>smallint</returnvalue>
20444 </para>
20445 <para role="func_signature">
20446 <function>bit_and</function> ( <type>integer</type> )
20447 <returnvalue>integer</returnvalue>
20448 </para>
20449 <para role="func_signature">
20450 <function>bit_and</function> ( <type>bigint</type> )
20451 <returnvalue>bigint</returnvalue>
20452 </para>
20453 <para role="func_signature">
20454 <function>bit_and</function> ( <type>bit</type> )
20455 <returnvalue>bit</returnvalue>
20456 </para>
20457 <para>
20458 Computes the bitwise AND of all non-null input values.
20459 </para></entry>
20460 <entry>Yes</entry>
20461 </row>
20463 <row>
20464 <entry role="func_table_entry"><para role="func_signature">
20465 <indexterm>
20466 <primary>bit_or</primary>
20467 </indexterm>
20468 <function>bit_or</function> ( <type>smallint</type> )
20469 <returnvalue>smallint</returnvalue>
20470 </para>
20471 <para role="func_signature">
20472 <function>bit_or</function> ( <type>integer</type> )
20473 <returnvalue>integer</returnvalue>
20474 </para>
20475 <para role="func_signature">
20476 <function>bit_or</function> ( <type>bigint</type> )
20477 <returnvalue>bigint</returnvalue>
20478 </para>
20479 <para role="func_signature">
20480 <function>bit_or</function> ( <type>bit</type> )
20481 <returnvalue>bit</returnvalue>
20482 </para>
20483 <para>
20484 Computes the bitwise OR of all non-null input values.
20485 </para></entry>
20486 <entry>Yes</entry>
20487 </row>
20489 <row>
20490 <entry role="func_table_entry"><para role="func_signature">
20491 <indexterm>
20492 <primary>bit_xor</primary>
20493 </indexterm>
20494 <function>bit_xor</function> ( <type>smallint</type> )
20495 <returnvalue>smallint</returnvalue>
20496 </para>
20497 <para role="func_signature">
20498 <function>bit_xor</function> ( <type>integer</type> )
20499 <returnvalue>integer</returnvalue>
20500 </para>
20501 <para role="func_signature">
20502 <function>bit_xor</function> ( <type>bigint</type> )
20503 <returnvalue>bigint</returnvalue>
20504 </para>
20505 <para role="func_signature">
20506 <function>bit_xor</function> ( <type>bit</type> )
20507 <returnvalue>bit</returnvalue>
20508 </para>
20509 <para>
20510 Computes the bitwise exclusive OR of all non-null input values.
20511 Can be useful as a checksum for an unordered set of values.
20512 </para></entry>
20513 <entry>Yes</entry>
20514 </row>
20516 <row>
20517 <entry role="func_table_entry"><para role="func_signature">
20518 <indexterm>
20519 <primary>bool_and</primary>
20520 </indexterm>
20521 <function>bool_and</function> ( <type>boolean</type> )
20522 <returnvalue>boolean</returnvalue>
20523 </para>
20524 <para>
20525 Returns true if all non-null input values are true, otherwise false.
20526 </para></entry>
20527 <entry>Yes</entry>
20528 </row>
20530 <row>
20531 <entry role="func_table_entry"><para role="func_signature">
20532 <indexterm>
20533 <primary>bool_or</primary>
20534 </indexterm>
20535 <function>bool_or</function> ( <type>boolean</type> )
20536 <returnvalue>boolean</returnvalue>
20537 </para>
20538 <para>
20539 Returns true if any non-null input value is true, otherwise false.
20540 </para></entry>
20541 <entry>Yes</entry>
20542 </row>
20544 <row>
20545 <entry role="func_table_entry"><para role="func_signature">
20546 <indexterm>
20547 <primary>count</primary>
20548 </indexterm>
20549 <function>count</function> ( <literal>*</literal> )
20550 <returnvalue>bigint</returnvalue>
20551 </para>
20552 <para>
20553 Computes the number of input rows.
20554 </para></entry>
20555 <entry>Yes</entry>
20556 </row>
20558 <row>
20559 <entry role="func_table_entry"><para role="func_signature">
20560 <function>count</function> ( <type>"any"</type> )
20561 <returnvalue>bigint</returnvalue>
20562 </para>
20563 <para>
20564 Computes the number of input rows in which the input value is not
20565 null.
20566 </para></entry>
20567 <entry>Yes</entry>
20568 </row>
20570 <row>
20571 <entry role="func_table_entry"><para role="func_signature">
20572 <indexterm>
20573 <primary>every</primary>
20574 </indexterm>
20575 <function>every</function> ( <type>boolean</type> )
20576 <returnvalue>boolean</returnvalue>
20577 </para>
20578 <para>
20579 This is the SQL standard's equivalent to <function>bool_and</function>.
20580 </para></entry>
20581 <entry>Yes</entry>
20582 </row>
20584 <row>
20585 <entry role="func_table_entry"><para role="func_signature">
20586 <indexterm>
20587 <primary>json_agg</primary>
20588 </indexterm>
20589 <function>json_agg</function> ( <type>anyelement</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20590 <returnvalue>json</returnvalue>
20591 </para>
20592 <para role="func_signature">
20593 <indexterm>
20594 <primary>jsonb_agg</primary>
20595 </indexterm>
20596 <function>jsonb_agg</function> ( <type>anyelement</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20597 <returnvalue>jsonb</returnvalue>
20598 </para>
20599 <para>
20600 Collects all the input values, including nulls, into a JSON array.
20601 Values are converted to JSON as per <function>to_json</function>
20602 or <function>to_jsonb</function>.
20603 </para></entry>
20604 <entry>No</entry>
20605 </row>
20607 <row>
20608 <entry role="func_table_entry"><para role="func_signature">
20609 <indexterm><primary>json_objectagg</primary></indexterm>
20610 <function>json_objectagg</function> (
20611 <optional> { <replaceable>key_expression</replaceable> { <literal>VALUE</literal> | ':' } <replaceable>value_expression</replaceable> } </optional>
20612 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
20613 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
20614 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
20615 </para>
20616 <para>
20617 Behaves like <function>json_object</function><!-- xref -->, but as an
20618 aggregate function, so it only takes one
20619 <replaceable>key_expression</replaceable> and one
20620 <replaceable>value_expression</replaceable> parameter.
20621 </para>
20622 <para>
20623 <literal>SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date + 1)) AS t(k,v)</literal>
20624 <returnvalue>{ "a" : "2022-05-10", "b" : "2022-05-11" }</returnvalue>
20625 </para></entry>
20626 <entry>No</entry>
20627 </row>
20629 <row>
20630 <entry role="func_table_entry"><para role="func_signature">
20631 <indexterm>
20632 <primary>json_object_agg</primary>
20633 </indexterm>
20634 <function>json_object_agg</function> ( <parameter>key</parameter>
20635 <type>"any"</type>, <parameter>value</parameter>
20636 <type>"any"</type>
20637 <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20638 <returnvalue>json</returnvalue>
20639 </para>
20640 <para role="func_signature">
20641 <indexterm>
20642 <primary>jsonb_object_agg</primary>
20643 </indexterm>
20644 <function>jsonb_object_agg</function> ( <parameter>key</parameter>
20645 <type>"any"</type>, <parameter>value</parameter>
20646 <type>"any"</type>
20647 <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20648 <returnvalue>jsonb</returnvalue>
20649 </para>
20650 <para>
20651 Collects all the key/value pairs into a JSON object. Key arguments
20652 are coerced to text; value arguments are converted as per
20653 <function>to_json</function> or <function>to_jsonb</function>.
20654 Values can be null, but keys cannot.
20655 </para></entry>
20656 <entry>No</entry>
20657 </row>
20659 <row>
20660 <entry role="func_table_entry"><para role="func_signature">
20661 <indexterm>
20662 <primary>json_object_agg_strict</primary>
20663 </indexterm>
20664 <function>json_object_agg_strict</function> (
20665 <parameter>key</parameter> <type>"any"</type>,
20666 <parameter>value</parameter> <type>"any"</type> )
20667 <returnvalue>json</returnvalue>
20668 </para>
20669 <para role="func_signature">
20670 <indexterm>
20671 <primary>jsonb_object_agg_strict</primary>
20672 </indexterm>
20673 <function>jsonb_object_agg_strict</function> (
20674 <parameter>key</parameter> <type>"any"</type>,
20675 <parameter>value</parameter> <type>"any"</type> )
20676 <returnvalue>jsonb</returnvalue>
20677 </para>
20678 <para>
20679 Collects all the key/value pairs into a JSON object. Key arguments
20680 are coerced to text; value arguments are converted as per
20681 <function>to_json</function> or <function>to_jsonb</function>.
20682 The <parameter>key</parameter> can not be null. If the
20683 <parameter>value</parameter> is null then the entry is skipped,
20684 </para></entry>
20685 <entry>No</entry>
20686 </row>
20688 <row>
20689 <entry role="func_table_entry"><para role="func_signature">
20690 <indexterm>
20691 <primary>json_object_agg_unique</primary>
20692 </indexterm>
20693 <function>json_object_agg_unique</function> (
20694 <parameter>key</parameter> <type>"any"</type>,
20695 <parameter>value</parameter> <type>"any"</type> )
20696 <returnvalue>json</returnvalue>
20697 </para>
20698 <para role="func_signature">
20699 <indexterm>
20700 <primary>jsonb_object_agg_unique</primary>
20701 </indexterm>
20702 <function>jsonb_object_agg_unique</function> (
20703 <parameter>key</parameter> <type>"any"</type>,
20704 <parameter>value</parameter> <type>"any"</type> )
20705 <returnvalue>jsonb</returnvalue>
20706 </para>
20707 <para>
20708 Collects all the key/value pairs into a JSON object. Key arguments
20709 are coerced to text; value arguments are converted as per
20710 <function>to_json</function> or <function>to_jsonb</function>.
20711 Values can be null, but keys cannot.
20712 If there is a duplicate key an error is thrown.
20713 </para></entry>
20714 <entry>No</entry>
20715 </row>
20717 <row>
20718 <entry role="func_table_entry"><para role="func_signature">
20719 <indexterm><primary>json_arrayagg</primary></indexterm>
20720 <function>json_arrayagg</function> (
20721 <optional> <replaceable>value_expression</replaceable> </optional>
20722 <optional> <literal>ORDER BY</literal> <replaceable>sort_expression</replaceable> </optional>
20723 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
20724 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
20725 </para>
20726 <para>
20727 Behaves in the same way as <function>json_array</function>
20728 but as an aggregate function so it only takes one
20729 <replaceable>value_expression</replaceable> parameter.
20730 If <literal>ABSENT ON NULL</literal> is specified, any NULL
20731 values are omitted.
20732 If <literal>ORDER BY</literal> is specified, the elements will
20733 appear in the array in that order rather than in the input order.
20734 </para>
20735 <para>
20736 <literal>SELECT json_arrayagg(v) FROM (VALUES(2),(1)) t(v)</literal>
20737 <returnvalue>[2, 1]</returnvalue>
20738 </para></entry>
20739 <entry>No</entry>
20740 </row>
20742 <row>
20743 <entry role="func_table_entry"><para role="func_signature">
20744 <indexterm>
20745 <primary>json_object_agg_unique_strict</primary>
20746 </indexterm>
20747 <function>json_object_agg_unique_strict</function> (
20748 <parameter>key</parameter> <type>"any"</type>,
20749 <parameter>value</parameter> <type>"any"</type> )
20750 <returnvalue>json</returnvalue>
20751 </para>
20752 <para role="func_signature">
20753 <indexterm>
20754 <primary>jsonb_object_agg_unique_strict</primary>
20755 </indexterm>
20756 <function>jsonb_object_agg_unique_strict</function> (
20757 <parameter>key</parameter> <type>"any"</type>,
20758 <parameter>value</parameter> <type>"any"</type> )
20759 <returnvalue>jsonb</returnvalue>
20760 </para>
20761 <para>
20762 Collects all the key/value pairs into a JSON object. Key arguments
20763 are coerced to text; value arguments are converted as per
20764 <function>to_json</function> or <function>to_jsonb</function>.
20765 The <parameter>key</parameter> can not be null. If the
20766 <parameter>value</parameter> is null then the entry is skipped.
20767 If there is a duplicate key an error is thrown.
20768 </para></entry>
20769 <entry>No</entry>
20770 </row>
20772 <row>
20773 <entry role="func_table_entry"><para role="func_signature">
20774 <indexterm>
20775 <primary>max</primary>
20776 </indexterm>
20777 <function>max</function> ( <replaceable>see text</replaceable> )
20778 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
20779 </para>
20780 <para>
20781 Computes the maximum of the non-null input
20782 values. Available for any numeric, string, date/time, or enum type,
20783 as well as <type>inet</type>, <type>interval</type>,
20784 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
20785 <type>tid</type>, <type>xid8</type>,
20786 and arrays of any of these types.
20787 </para></entry>
20788 <entry>Yes</entry>
20789 </row>
20791 <row>
20792 <entry role="func_table_entry"><para role="func_signature">
20793 <indexterm>
20794 <primary>min</primary>
20795 </indexterm>
20796 <function>min</function> ( <replaceable>see text</replaceable> )
20797 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
20798 </para>
20799 <para>
20800 Computes the minimum of the non-null input
20801 values. Available for any numeric, string, date/time, or enum type,
20802 as well as <type>inet</type>, <type>interval</type>,
20803 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
20804 <type>tid</type>, <type>xid8</type>,
20805 and arrays of any of these types.
20806 </para></entry>
20807 <entry>Yes</entry>
20808 </row>
20810 <row>
20811 <entry role="func_table_entry"><para role="func_signature">
20812 <indexterm>
20813 <primary>range_agg</primary>
20814 </indexterm>
20815 <function>range_agg</function> ( <parameter>value</parameter>
20816 <type>anyrange</type> )
20817 <returnvalue>anymultirange</returnvalue>
20818 </para>
20819 <para role="func_signature">
20820 <function>range_agg</function> ( <parameter>value</parameter>
20821 <type>anymultirange</type> )
20822 <returnvalue>anymultirange</returnvalue>
20823 </para>
20824 <para>
20825 Computes the union of the non-null input values.
20826 </para></entry>
20827 <entry>No</entry>
20828 </row>
20830 <row>
20831 <entry role="func_table_entry"><para role="func_signature">
20832 <indexterm>
20833 <primary>range_intersect_agg</primary>
20834 </indexterm>
20835 <function>range_intersect_agg</function> ( <parameter>value</parameter>
20836 <type>anyrange</type> )
20837 <returnvalue>anyrange</returnvalue>
20838 </para>
20839 <para role="func_signature">
20840 <function>range_intersect_agg</function> ( <parameter>value</parameter>
20841 <type>anymultirange</type> )
20842 <returnvalue>anymultirange</returnvalue>
20843 </para>
20844 <para>
20845 Computes the intersection of the non-null input values.
20846 </para></entry>
20847 <entry>No</entry>
20848 </row>
20850 <row>
20851 <entry role="func_table_entry"><para role="func_signature">
20852 <indexterm>
20853 <primary>json_agg_strict</primary>
20854 </indexterm>
20855 <function>json_agg_strict</function> ( <type>anyelement</type> )
20856 <returnvalue>json</returnvalue>
20857 </para>
20858 <para role="func_signature">
20859 <indexterm>
20860 <primary>jsonb_agg_strict</primary>
20861 </indexterm>
20862 <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
20863 <returnvalue>jsonb</returnvalue>
20864 </para>
20865 <para>
20866 Collects all the input values, skipping nulls, into a JSON array.
20867 Values are converted to JSON as per <function>to_json</function>
20868 or <function>to_jsonb</function>.
20869 </para></entry>
20870 <entry>No</entry>
20871 </row>
20873 <row>
20874 <entry role="func_table_entry"><para role="func_signature">
20875 <indexterm>
20876 <primary>string_agg</primary>
20877 </indexterm>
20878 <function>string_agg</function> ( <parameter>value</parameter>
20879 <type>text</type>, <parameter>delimiter</parameter> <type>text</type> )
20880 <returnvalue>text</returnvalue>
20881 </para>
20882 <para role="func_signature">
20883 <function>string_agg</function> ( <parameter>value</parameter>
20884 <type>bytea</type>, <parameter>delimiter</parameter> <type>bytea</type>
20885 <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20886 <returnvalue>bytea</returnvalue>
20887 </para>
20888 <para>
20889 Concatenates the non-null input values into a string. Each value
20890 after the first is preceded by the
20891 corresponding <parameter>delimiter</parameter> (if it's not null).
20892 </para></entry>
20893 <entry>Yes</entry>
20894 </row>
20896 <row>
20897 <entry role="func_table_entry"><para role="func_signature">
20898 <indexterm>
20899 <primary>sum</primary>
20900 </indexterm>
20901 <function>sum</function> ( <type>smallint</type> )
20902 <returnvalue>bigint</returnvalue>
20903 </para>
20904 <para role="func_signature">
20905 <function>sum</function> ( <type>integer</type> )
20906 <returnvalue>bigint</returnvalue>
20907 </para>
20908 <para role="func_signature">
20909 <function>sum</function> ( <type>bigint</type> )
20910 <returnvalue>numeric</returnvalue>
20911 </para>
20912 <para role="func_signature">
20913 <function>sum</function> ( <type>numeric</type> )
20914 <returnvalue>numeric</returnvalue>
20915 </para>
20916 <para role="func_signature">
20917 <function>sum</function> ( <type>real</type> )
20918 <returnvalue>real</returnvalue>
20919 </para>
20920 <para role="func_signature">
20921 <function>sum</function> ( <type>double precision</type> )
20922 <returnvalue>double precision</returnvalue>
20923 </para>
20924 <para role="func_signature">
20925 <function>sum</function> ( <type>interval</type> )
20926 <returnvalue>interval</returnvalue>
20927 </para>
20928 <para role="func_signature">
20929 <function>sum</function> ( <type>money</type> )
20930 <returnvalue>money</returnvalue>
20931 </para>
20932 <para>
20933 Computes the sum of the non-null input values.
20934 </para></entry>
20935 <entry>Yes</entry>
20936 </row>
20938 <row>
20939 <entry role="func_table_entry"><para role="func_signature">
20940 <indexterm>
20941 <primary>xmlagg</primary>
20942 </indexterm>
20943 <function>xmlagg</function> ( <type>xml</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
20944 <returnvalue>xml</returnvalue>
20945 </para>
20946 <para>
20947 Concatenates the non-null XML input values (see
20948 <xref linkend="functions-xml-xmlagg"/>).
20949 </para></entry>
20950 <entry>No</entry>
20951 </row>
20952 </tbody>
20953 </tgroup>
20954 </table>
20956 <para>
20957 It should be noted that except for <function>count</function>,
20958 these functions return a null value when no rows are selected. In
20959 particular, <function>sum</function> of no rows returns null, not
20960 zero as one might expect, and <function>array_agg</function>
20961 returns null rather than an empty array when there are no input
20962 rows. The <function>coalesce</function> function can be used to
20963 substitute zero or an empty array for null when necessary.
20964 </para>
20966 <para>
20967 The aggregate functions <function>array_agg</function>,
20968 <function>json_agg</function>, <function>jsonb_agg</function>,
20969 <function>json_agg_strict</function>, <function>jsonb_agg_strict</function>,
20970 <function>json_object_agg</function>, <function>jsonb_object_agg</function>,
20971 <function>json_object_agg_strict</function>, <function>jsonb_object_agg_strict</function>,
20972 <function>json_object_agg_unique</function>, <function>jsonb_object_agg_unique</function>,
20973 <function>json_object_agg_unique_strict</function>,
20974 <function>jsonb_object_agg_unique_strict</function>,
20975 <function>string_agg</function>,
20976 and <function>xmlagg</function>, as well as similar user-defined
20977 aggregate functions, produce meaningfully different result values
20978 depending on the order of the input values. This ordering is
20979 unspecified by default, but can be controlled by writing an
20980 <literal>ORDER BY</literal> clause within the aggregate call, as shown in
20981 <xref linkend="syntax-aggregates"/>.
20982 Alternatively, supplying the input values from a sorted subquery
20983 will usually work. For example:
20985 <screen><![CDATA[
20986 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
20987 ]]></screen>
20989 Beware that this approach can fail if the outer query level contains
20990 additional processing, such as a join, because that might cause the
20991 subquery's output to be reordered before the aggregate is computed.
20992 </para>
20994 <note>
20995 <indexterm>
20996 <primary>ANY</primary>
20997 </indexterm>
20998 <indexterm>
20999 <primary>SOME</primary>
21000 </indexterm>
21001 <para>
21002 The boolean aggregates <function>bool_and</function> and
21003 <function>bool_or</function> correspond to the standard SQL aggregates
21004 <function>every</function> and <function>any</function> or
21005 <function>some</function>.
21006 <productname>PostgreSQL</productname>
21007 supports <function>every</function>, but not <function>any</function>
21008 or <function>some</function>, because there is an ambiguity built into
21009 the standard syntax:
21010 <programlisting>
21011 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
21012 </programlisting>
21013 Here <function>ANY</function> can be considered either as introducing
21014 a subquery, or as being an aggregate function, if the subquery
21015 returns one row with a Boolean value.
21016 Thus the standard name cannot be given to these aggregates.
21017 </para>
21018 </note>
21020 <note>
21021 <para>
21022 Users accustomed to working with other SQL database management
21023 systems might be disappointed by the performance of the
21024 <function>count</function> aggregate when it is applied to the
21025 entire table. A query like:
21026 <programlisting>
21027 SELECT count(*) FROM sometable;
21028 </programlisting>
21029 will require effort proportional to the size of the table:
21030 <productname>PostgreSQL</productname> will need to scan either the
21031 entire table or the entirety of an index that includes all rows in
21032 the table.
21033 </para>
21034 </note>
21036 <para>
21037 <xref linkend="functions-aggregate-statistics-table"/> shows
21038 aggregate functions typically used in statistical analysis.
21039 (These are separated out merely to avoid cluttering the listing
21040 of more-commonly-used aggregates.) Functions shown as
21041 accepting <replaceable>numeric_type</replaceable> are available for all
21042 the types <type>smallint</type>, <type>integer</type>,
21043 <type>bigint</type>, <type>numeric</type>, <type>real</type>,
21044 and <type>double precision</type>.
21045 Where the description mentions
21046 <parameter>N</parameter>, it means the
21047 number of input rows for which all the input expressions are non-null.
21048 In all cases, null is returned if the computation is meaningless,
21049 for example when <parameter>N</parameter> is zero.
21050 </para>
21052 <indexterm>
21053 <primary>statistics</primary>
21054 </indexterm>
21055 <indexterm>
21056 <primary>linear regression</primary>
21057 </indexterm>
21059 <table id="functions-aggregate-statistics-table">
21060 <title>Aggregate Functions for Statistics</title>
21061 <tgroup cols="2">
21062 <colspec colname="col1" colwidth="10*"/>
21063 <colspec colname="col2" colwidth="1*"/>
21064 <thead>
21065 <row>
21066 <entry role="func_table_entry"><para role="func_signature">
21067 Function
21068 </para>
21069 <para>
21070 Description
21071 </para></entry>
21072 <entry>Partial Mode</entry>
21073 </row>
21074 </thead>
21076 <tbody>
21077 <row>
21078 <entry role="func_table_entry"><para role="func_signature">
21079 <indexterm>
21080 <primary>correlation</primary>
21081 </indexterm>
21082 <indexterm>
21083 <primary>corr</primary>
21084 </indexterm>
21085 <function>corr</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21086 <returnvalue>double precision</returnvalue>
21087 </para>
21088 <para>
21089 Computes the correlation coefficient.
21090 </para></entry>
21091 <entry>Yes</entry>
21092 </row>
21094 <row>
21095 <entry role="func_table_entry"><para role="func_signature">
21096 <indexterm>
21097 <primary>covariance</primary>
21098 <secondary>population</secondary>
21099 </indexterm>
21100 <indexterm>
21101 <primary>covar_pop</primary>
21102 </indexterm>
21103 <function>covar_pop</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21104 <returnvalue>double precision</returnvalue>
21105 </para>
21106 <para>
21107 Computes the population covariance.
21108 </para></entry>
21109 <entry>Yes</entry>
21110 </row>
21112 <row>
21113 <entry role="func_table_entry"><para role="func_signature">
21114 <indexterm>
21115 <primary>covariance</primary>
21116 <secondary>sample</secondary>
21117 </indexterm>
21118 <indexterm>
21119 <primary>covar_samp</primary>
21120 </indexterm>
21121 <function>covar_samp</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21122 <returnvalue>double precision</returnvalue>
21123 </para>
21124 <para>
21125 Computes the sample covariance.
21126 </para></entry>
21127 <entry>Yes</entry>
21128 </row>
21130 <row>
21131 <entry role="func_table_entry"><para role="func_signature">
21132 <indexterm>
21133 <primary>regr_avgx</primary>
21134 </indexterm>
21135 <function>regr_avgx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21136 <returnvalue>double precision</returnvalue>
21137 </para>
21138 <para>
21139 Computes the average of the independent variable,
21140 <literal>sum(<parameter>X</parameter>)/<parameter>N</parameter></literal>.
21141 </para></entry>
21142 <entry>Yes</entry>
21143 </row>
21145 <row>
21146 <entry role="func_table_entry"><para role="func_signature">
21147 <indexterm>
21148 <primary>regr_avgy</primary>
21149 </indexterm>
21150 <function>regr_avgy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21151 <returnvalue>double precision</returnvalue>
21152 </para>
21153 <para>
21154 Computes the average of the dependent variable,
21155 <literal>sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
21156 </para></entry>
21157 <entry>Yes</entry>
21158 </row>
21160 <row>
21161 <entry role="func_table_entry"><para role="func_signature">
21162 <indexterm>
21163 <primary>regr_count</primary>
21164 </indexterm>
21165 <function>regr_count</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21166 <returnvalue>bigint</returnvalue>
21167 </para>
21168 <para>
21169 Computes the number of rows in which both inputs are non-null.
21170 </para></entry>
21171 <entry>Yes</entry>
21172 </row>
21174 <row>
21175 <entry role="func_table_entry"><para role="func_signature">
21176 <indexterm>
21177 <primary>regression intercept</primary>
21178 </indexterm>
21179 <indexterm>
21180 <primary>regr_intercept</primary>
21181 </indexterm>
21182 <function>regr_intercept</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21183 <returnvalue>double precision</returnvalue>
21184 </para>
21185 <para>
21186 Computes the y-intercept of the least-squares-fit linear equation
21187 determined by the
21188 (<parameter>X</parameter>, <parameter>Y</parameter>) pairs.
21189 </para></entry>
21190 <entry>Yes</entry>
21191 </row>
21193 <row>
21194 <entry role="func_table_entry"><para role="func_signature">
21195 <indexterm>
21196 <primary>regr_r2</primary>
21197 </indexterm>
21198 <function>regr_r2</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21199 <returnvalue>double precision</returnvalue>
21200 </para>
21201 <para>
21202 Computes the square of the correlation coefficient.
21203 </para></entry>
21204 <entry>Yes</entry>
21205 </row>
21207 <row>
21208 <entry role="func_table_entry"><para role="func_signature">
21209 <indexterm>
21210 <primary>regression slope</primary>
21211 </indexterm>
21212 <indexterm>
21213 <primary>regr_slope</primary>
21214 </indexterm>
21215 <function>regr_slope</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21216 <returnvalue>double precision</returnvalue>
21217 </para>
21218 <para>
21219 Computes the slope of the least-squares-fit linear equation determined
21220 by the (<parameter>X</parameter>, <parameter>Y</parameter>)
21221 pairs.
21222 </para></entry>
21223 <entry>Yes</entry>
21224 </row>
21226 <row>
21227 <entry role="func_table_entry"><para role="func_signature">
21228 <indexterm>
21229 <primary>regr_sxx</primary>
21230 </indexterm>
21231 <function>regr_sxx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21232 <returnvalue>double precision</returnvalue>
21233 </para>
21234 <para>
21235 Computes the <quote>sum of squares</quote> of the independent
21236 variable,
21237 <literal>sum(<parameter>X</parameter>^2) - sum(<parameter>X</parameter>)^2/<parameter>N</parameter></literal>.
21238 </para></entry>
21239 <entry>Yes</entry>
21240 </row>
21242 <row>
21243 <entry role="func_table_entry"><para role="func_signature">
21244 <indexterm>
21245 <primary>regr_sxy</primary>
21246 </indexterm>
21247 <function>regr_sxy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21248 <returnvalue>double precision</returnvalue>
21249 </para>
21250 <para>
21251 Computes the <quote>sum of products</quote> of independent times
21252 dependent variables,
21253 <literal>sum(<parameter>X</parameter>*<parameter>Y</parameter>) - sum(<parameter>X</parameter>) * sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
21254 </para></entry>
21255 <entry>Yes</entry>
21256 </row>
21258 <row>
21259 <entry role="func_table_entry"><para role="func_signature">
21260 <indexterm>
21261 <primary>regr_syy</primary>
21262 </indexterm>
21263 <function>regr_syy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21264 <returnvalue>double precision</returnvalue>
21265 </para>
21266 <para>
21267 Computes the <quote>sum of squares</quote> of the dependent
21268 variable,
21269 <literal>sum(<parameter>Y</parameter>^2) - sum(<parameter>Y</parameter>)^2/<parameter>N</parameter></literal>.
21270 </para></entry>
21271 <entry>Yes</entry>
21272 </row>
21274 <row>
21275 <entry role="func_table_entry"><para role="func_signature">
21276 <indexterm>
21277 <primary>standard deviation</primary>
21278 </indexterm>
21279 <indexterm>
21280 <primary>stddev</primary>
21281 </indexterm>
21282 <function>stddev</function> ( <replaceable>numeric_type</replaceable> )
21283 <returnvalue></returnvalue> <type>double precision</type>
21284 for <type>real</type> or <type>double precision</type>,
21285 otherwise <type>numeric</type>
21286 </para>
21287 <para>
21288 This is a historical alias for <function>stddev_samp</function>.
21289 </para></entry>
21290 <entry>Yes</entry>
21291 </row>
21293 <row>
21294 <entry role="func_table_entry"><para role="func_signature">
21295 <indexterm>
21296 <primary>standard deviation</primary>
21297 <secondary>population</secondary>
21298 </indexterm>
21299 <indexterm>
21300 <primary>stddev_pop</primary>
21301 </indexterm>
21302 <function>stddev_pop</function> ( <replaceable>numeric_type</replaceable> )
21303 <returnvalue></returnvalue> <type>double precision</type>
21304 for <type>real</type> or <type>double precision</type>,
21305 otherwise <type>numeric</type>
21306 </para>
21307 <para>
21308 Computes the population standard deviation of the input values.
21309 </para></entry>
21310 <entry>Yes</entry>
21311 </row>
21313 <row>
21314 <entry role="func_table_entry"><para role="func_signature">
21315 <indexterm>
21316 <primary>standard deviation</primary>
21317 <secondary>sample</secondary>
21318 </indexterm>
21319 <indexterm>
21320 <primary>stddev_samp</primary>
21321 </indexterm>
21322 <function>stddev_samp</function> ( <replaceable>numeric_type</replaceable> )
21323 <returnvalue></returnvalue> <type>double precision</type>
21324 for <type>real</type> or <type>double precision</type>,
21325 otherwise <type>numeric</type>
21326 </para>
21327 <para>
21328 Computes the sample standard deviation of the input values.
21329 </para></entry>
21330 <entry>Yes</entry>
21331 </row>
21333 <row>
21334 <entry role="func_table_entry"><para role="func_signature">
21335 <indexterm>
21336 <primary>variance</primary>
21337 </indexterm>
21338 <function>variance</function> ( <replaceable>numeric_type</replaceable> )
21339 <returnvalue></returnvalue> <type>double precision</type>
21340 for <type>real</type> or <type>double precision</type>,
21341 otherwise <type>numeric</type>
21342 </para>
21343 <para>
21344 This is a historical alias for <function>var_samp</function>.
21345 </para></entry>
21346 <entry>Yes</entry>
21347 </row>
21349 <row>
21350 <entry role="func_table_entry"><para role="func_signature">
21351 <indexterm>
21352 <primary>variance</primary>
21353 <secondary>population</secondary>
21354 </indexterm>
21355 <indexterm>
21356 <primary>var_pop</primary>
21357 </indexterm>
21358 <function>var_pop</function> ( <replaceable>numeric_type</replaceable> )
21359 <returnvalue></returnvalue> <type>double precision</type>
21360 for <type>real</type> or <type>double precision</type>,
21361 otherwise <type>numeric</type>
21362 </para>
21363 <para>
21364 Computes the population variance of the input values (square of the
21365 population standard deviation).
21366 </para></entry>
21367 <entry>Yes</entry>
21368 </row>
21370 <row>
21371 <entry role="func_table_entry"><para role="func_signature">
21372 <indexterm>
21373 <primary>variance</primary>
21374 <secondary>sample</secondary>
21375 </indexterm>
21376 <indexterm>
21377 <primary>var_samp</primary>
21378 </indexterm>
21379 <function>var_samp</function> ( <replaceable>numeric_type</replaceable> )
21380 <returnvalue></returnvalue> <type>double precision</type>
21381 for <type>real</type> or <type>double precision</type>,
21382 otherwise <type>numeric</type>
21383 </para>
21384 <para>
21385 Computes the sample variance of the input values (square of the sample
21386 standard deviation).
21387 </para></entry>
21388 <entry>Yes</entry>
21389 </row>
21390 </tbody>
21391 </tgroup>
21392 </table>
21394 <para>
21395 <xref linkend="functions-orderedset-table"/> shows some
21396 aggregate functions that use the <firstterm>ordered-set aggregate</firstterm>
21397 syntax. These functions are sometimes referred to as <quote>inverse
21398 distribution</quote> functions. Their aggregated input is introduced by
21399 <literal>ORDER BY</literal>, and they may also take a <firstterm>direct
21400 argument</firstterm> that is not aggregated, but is computed only once.
21401 All these functions ignore null values in their aggregated input.
21402 For those that take a <parameter>fraction</parameter> parameter, the
21403 fraction value must be between 0 and 1; an error is thrown if not.
21404 However, a null <parameter>fraction</parameter> value simply produces a
21405 null result.
21406 </para>
21408 <indexterm>
21409 <primary>ordered-set aggregate</primary>
21410 <secondary>built-in</secondary>
21411 </indexterm>
21412 <indexterm>
21413 <primary>inverse distribution</primary>
21414 </indexterm>
21416 <table id="functions-orderedset-table">
21417 <title>Ordered-Set Aggregate Functions</title>
21418 <tgroup cols="2">
21419 <colspec colname="col1" colwidth="10*"/>
21420 <colspec colname="col2" colwidth="1*"/>
21421 <thead>
21422 <row>
21423 <entry role="func_table_entry"><para role="func_signature">
21424 Function
21425 </para>
21426 <para>
21427 Description
21428 </para></entry>
21429 <entry>Partial Mode</entry>
21430 </row>
21431 </thead>
21433 <tbody>
21434 <row>
21435 <entry role="func_table_entry"><para role="func_signature">
21436 <indexterm>
21437 <primary>mode</primary>
21438 <secondary>statistical</secondary>
21439 </indexterm>
21440 <function>mode</function> () <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21441 <returnvalue>anyelement</returnvalue>
21442 </para>
21443 <para>
21444 Computes the <firstterm>mode</firstterm>, the most frequent
21445 value of the aggregated argument (arbitrarily choosing the first one
21446 if there are multiple equally-frequent values). The aggregated
21447 argument must be of a sortable type.
21448 </para></entry>
21449 <entry>No</entry>
21450 </row>
21452 <row>
21453 <entry role="func_table_entry"><para role="func_signature">
21454 <indexterm>
21455 <primary>percentile</primary>
21456 <secondary>continuous</secondary>
21457 </indexterm>
21458 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
21459 <returnvalue>double precision</returnvalue>
21460 </para>
21461 <para role="func_signature">
21462 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
21463 <returnvalue>interval</returnvalue>
21464 </para>
21465 <para>
21466 Computes the <firstterm>continuous percentile</firstterm>, a value
21467 corresponding to the specified <parameter>fraction</parameter>
21468 within the ordered set of aggregated argument values. This will
21469 interpolate between adjacent input items if needed.
21470 </para></entry>
21471 <entry>No</entry>
21472 </row>
21474 <row>
21475 <entry role="func_table_entry"><para role="func_signature">
21476 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
21477 <returnvalue>double precision[]</returnvalue>
21478 </para>
21479 <para role="func_signature">
21480 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
21481 <returnvalue>interval[]</returnvalue>
21482 </para>
21483 <para>
21484 Computes multiple continuous percentiles. The result is an array of
21485 the same dimensions as the <parameter>fractions</parameter>
21486 parameter, with each non-null element replaced by the (possibly
21487 interpolated) value corresponding to that percentile.
21488 </para></entry>
21489 <entry>No</entry>
21490 </row>
21492 <row>
21493 <entry role="func_table_entry"><para role="func_signature">
21494 <indexterm>
21495 <primary>percentile</primary>
21496 <secondary>discrete</secondary>
21497 </indexterm>
21498 <function>percentile_disc</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21499 <returnvalue>anyelement</returnvalue>
21500 </para>
21501 <para>
21502 Computes the <firstterm>discrete percentile</firstterm>, the first
21503 value within the ordered set of aggregated argument values whose
21504 position in the ordering equals or exceeds the
21505 specified <parameter>fraction</parameter>. The aggregated
21506 argument must be of a sortable type.
21507 </para></entry>
21508 <entry>No</entry>
21509 </row>
21511 <row>
21512 <entry role="func_table_entry"><para role="func_signature">
21513 <function>percentile_disc</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21514 <returnvalue>anyarray</returnvalue>
21515 </para>
21516 <para>
21517 Computes multiple discrete percentiles. The result is an array of the
21518 same dimensions as the <parameter>fractions</parameter> parameter,
21519 with each non-null element replaced by the input value corresponding
21520 to that percentile.
21521 The aggregated argument must be of a sortable type.
21522 </para></entry>
21523 <entry>No</entry>
21524 </row>
21525 </tbody>
21526 </tgroup>
21527 </table>
21529 <indexterm>
21530 <primary>hypothetical-set aggregate</primary>
21531 <secondary>built-in</secondary>
21532 </indexterm>
21534 <para>
21535 Each of the <quote>hypothetical-set</quote> aggregates listed in
21536 <xref linkend="functions-hypothetical-table"/> is associated with a
21537 window function of the same name defined in
21538 <xref linkend="functions-window"/>. In each case, the aggregate's result
21539 is the value that the associated window function would have
21540 returned for the <quote>hypothetical</quote> row constructed from
21541 <replaceable>args</replaceable>, if such a row had been added to the sorted
21542 group of rows represented by the <replaceable>sorted_args</replaceable>.
21543 For each of these functions, the list of direct arguments
21544 given in <replaceable>args</replaceable> must match the number and types of
21545 the aggregated arguments given in <replaceable>sorted_args</replaceable>.
21546 Unlike most built-in aggregates, these aggregates are not strict, that is
21547 they do not drop input rows containing nulls. Null values sort according
21548 to the rule specified in the <literal>ORDER BY</literal> clause.
21549 </para>
21551 <table id="functions-hypothetical-table">
21552 <title>Hypothetical-Set Aggregate Functions</title>
21553 <tgroup cols="2">
21554 <colspec colname="col1" colwidth="10*"/>
21555 <colspec colname="col2" colwidth="1*"/>
21556 <thead>
21557 <row>
21558 <entry role="func_table_entry"><para role="func_signature">
21559 Function
21560 </para>
21561 <para>
21562 Description
21563 </para></entry>
21564 <entry>Partial Mode</entry>
21565 </row>
21566 </thead>
21568 <tbody>
21569 <row>
21570 <entry role="func_table_entry"><para role="func_signature">
21571 <indexterm>
21572 <primary>rank</primary>
21573 <secondary>hypothetical</secondary>
21574 </indexterm>
21575 <function>rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21576 <returnvalue>bigint</returnvalue>
21577 </para>
21578 <para>
21579 Computes the rank of the hypothetical row, with gaps; that is, the row
21580 number of the first row in its peer group.
21581 </para></entry>
21582 <entry>No</entry>
21583 </row>
21585 <row>
21586 <entry role="func_table_entry"><para role="func_signature">
21587 <indexterm>
21588 <primary>dense_rank</primary>
21589 <secondary>hypothetical</secondary>
21590 </indexterm>
21591 <function>dense_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21592 <returnvalue>bigint</returnvalue>
21593 </para>
21594 <para>
21595 Computes the rank of the hypothetical row, without gaps; this function
21596 effectively counts peer groups.
21597 </para></entry>
21598 <entry>No</entry>
21599 </row>
21601 <row>
21602 <entry role="func_table_entry"><para role="func_signature">
21603 <indexterm>
21604 <primary>percent_rank</primary>
21605 <secondary>hypothetical</secondary>
21606 </indexterm>
21607 <function>percent_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21608 <returnvalue>double precision</returnvalue>
21609 </para>
21610 <para>
21611 Computes the relative rank of the hypothetical row, that is
21612 (<function>rank</function> - 1) / (total rows - 1).
21613 The value thus ranges from 0 to 1 inclusive.
21614 </para></entry>
21615 <entry>No</entry>
21616 </row>
21618 <row>
21619 <entry role="func_table_entry"><para role="func_signature">
21620 <indexterm>
21621 <primary>cume_dist</primary>
21622 <secondary>hypothetical</secondary>
21623 </indexterm>
21624 <function>cume_dist</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21625 <returnvalue>double precision</returnvalue>
21626 </para>
21627 <para>
21628 Computes the cumulative distribution, that is (number of rows
21629 preceding or peers with hypothetical row) / (total rows). The value
21630 thus ranges from 1/<parameter>N</parameter> to 1.
21631 </para></entry>
21632 <entry>No</entry>
21633 </row>
21634 </tbody>
21635 </tgroup>
21636 </table>
21638 <table id="functions-grouping-table">
21639 <title>Grouping Operations</title>
21640 <tgroup cols="1">
21641 <thead>
21642 <row>
21643 <entry role="func_table_entry"><para role="func_signature">
21644 Function
21645 </para>
21646 <para>
21647 Description
21648 </para></entry>
21649 </row>
21650 </thead>
21652 <tbody>
21653 <row>
21654 <entry role="func_table_entry"><para role="func_signature">
21655 <indexterm>
21656 <primary>GROUPING</primary>
21657 </indexterm>
21658 <function>GROUPING</function> ( <replaceable>group_by_expression(s)</replaceable> )
21659 <returnvalue>integer</returnvalue>
21660 </para>
21661 <para>
21662 Returns a bit mask indicating which <literal>GROUP BY</literal>
21663 expressions are not included in the current grouping set.
21664 Bits are assigned with the rightmost argument corresponding to the
21665 least-significant bit; each bit is 0 if the corresponding expression
21666 is included in the grouping criteria of the grouping set generating
21667 the current result row, and 1 if it is not included.
21668 </para></entry>
21669 </row>
21670 </tbody>
21671 </tgroup>
21672 </table>
21674 <para>
21675 The grouping operations shown in
21676 <xref linkend="functions-grouping-table"/> are used in conjunction with
21677 grouping sets (see <xref linkend="queries-grouping-sets"/>) to distinguish
21678 result rows. The arguments to the <literal>GROUPING</literal> function
21679 are not actually evaluated, but they must exactly match expressions given
21680 in the <literal>GROUP BY</literal> clause of the associated query level.
21681 For example:
21682 <screen>
21683 <prompt>=&gt;</prompt> <userinput>SELECT * FROM items_sold;</userinput>
21684 make | model | sales
21685 -------+-------+-------
21686 Foo | GT | 10
21687 Foo | Tour | 20
21688 Bar | City | 15
21689 Bar | Sport | 5
21690 (4 rows)
21692 <prompt>=&gt;</prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</userinput>
21693 make | model | grouping | sum
21694 -------+-------+----------+-----
21695 Foo | GT | 0 | 10
21696 Foo | Tour | 0 | 20
21697 Bar | City | 0 | 15
21698 Bar | Sport | 0 | 5
21699 Foo | | 1 | 30
21700 Bar | | 1 | 20
21701 | | 3 | 50
21702 (7 rows)
21703 </screen>
21704 Here, the <literal>grouping</literal> value <literal>0</literal> in the
21705 first four rows shows that those have been grouped normally, over both the
21706 grouping columns. The value <literal>1</literal> indicates
21707 that <literal>model</literal> was not grouped by in the next-to-last two
21708 rows, and the value <literal>3</literal> indicates that
21709 neither <literal>make</literal> nor <literal>model</literal> was grouped
21710 by in the last row (which therefore is an aggregate over all the input
21711 rows).
21712 </para>
21714 </sect1>
21716 <sect1 id="functions-window">
21717 <title>Window Functions</title>
21719 <indexterm zone="functions-window">
21720 <primary>window function</primary>
21721 <secondary>built-in</secondary>
21722 </indexterm>
21724 <para>
21725 <firstterm>Window functions</firstterm> provide the ability to perform
21726 calculations across sets of rows that are related to the current query
21727 row. See <xref linkend="tutorial-window"/> for an introduction to this
21728 feature, and <xref linkend="syntax-window-functions"/> for syntax
21729 details.
21730 </para>
21732 <para>
21733 The built-in window functions are listed in
21734 <xref linkend="functions-window-table"/>. Note that these functions
21735 <emphasis>must</emphasis> be invoked using window function syntax, i.e., an
21736 <literal>OVER</literal> clause is required.
21737 </para>
21739 <para>
21740 In addition to these functions, any built-in or user-defined
21741 ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates)
21742 can be used as a window function; see
21743 <xref linkend="functions-aggregate"/> for a list of the built-in aggregates.
21744 Aggregate functions act as window functions only when an <literal>OVER</literal>
21745 clause follows the call; otherwise they act as plain aggregates
21746 and return a single row for the entire set.
21747 </para>
21749 <table id="functions-window-table">
21750 <title>General-Purpose Window Functions</title>
21751 <tgroup cols="1">
21752 <thead>
21753 <row>
21754 <entry role="func_table_entry"><para role="func_signature">
21755 Function
21756 </para>
21757 <para>
21758 Description
21759 </para></entry>
21760 </row>
21761 </thead>
21763 <tbody>
21764 <row>
21765 <entry role="func_table_entry"><para role="func_signature">
21766 <indexterm>
21767 <primary>row_number</primary>
21768 </indexterm>
21769 <function>row_number</function> ()
21770 <returnvalue>bigint</returnvalue>
21771 </para>
21772 <para>
21773 Returns the number of the current row within its partition, counting
21774 from 1.
21775 </para></entry>
21776 </row>
21778 <row>
21779 <entry role="func_table_entry"><para role="func_signature">
21780 <indexterm>
21781 <primary>rank</primary>
21782 </indexterm>
21783 <function>rank</function> ()
21784 <returnvalue>bigint</returnvalue>
21785 </para>
21786 <para>
21787 Returns the rank of the current row, with gaps; that is,
21788 the <function>row_number</function> of the first row in its peer
21789 group.
21790 </para></entry>
21791 </row>
21793 <row>
21794 <entry role="func_table_entry"><para role="func_signature">
21795 <indexterm>
21796 <primary>dense_rank</primary>
21797 </indexterm>
21798 <function>dense_rank</function> ()
21799 <returnvalue>bigint</returnvalue>
21800 </para>
21801 <para>
21802 Returns the rank of the current row, without gaps; this function
21803 effectively counts peer groups.
21804 </para></entry>
21805 </row>
21807 <row>
21808 <entry role="func_table_entry"><para role="func_signature">
21809 <indexterm>
21810 <primary>percent_rank</primary>
21811 </indexterm>
21812 <function>percent_rank</function> ()
21813 <returnvalue>double precision</returnvalue>
21814 </para>
21815 <para>
21816 Returns the relative rank of the current row, that is
21817 (<function>rank</function> - 1) / (total partition rows - 1).
21818 The value thus ranges from 0 to 1 inclusive.
21819 </para></entry>
21820 </row>
21822 <row>
21823 <entry role="func_table_entry"><para role="func_signature">
21824 <indexterm>
21825 <primary>cume_dist</primary>
21826 </indexterm>
21827 <function>cume_dist</function> ()
21828 <returnvalue>double precision</returnvalue>
21829 </para>
21830 <para>
21831 Returns the cumulative distribution, that is (number of partition rows
21832 preceding or peers with current row) / (total partition rows).
21833 The value thus ranges from 1/<parameter>N</parameter> to 1.
21834 </para></entry>
21835 </row>
21837 <row>
21838 <entry role="func_table_entry"><para role="func_signature">
21839 <indexterm>
21840 <primary>ntile</primary>
21841 </indexterm>
21842 <function>ntile</function> ( <parameter>num_buckets</parameter> <type>integer</type> )
21843 <returnvalue>integer</returnvalue>
21844 </para>
21845 <para>
21846 Returns an integer ranging from 1 to the argument value, dividing the
21847 partition as equally as possible.
21848 </para></entry>
21849 </row>
21851 <row>
21852 <entry role="func_table_entry"><para role="func_signature">
21853 <indexterm>
21854 <primary>lag</primary>
21855 </indexterm>
21856 <function>lag</function> ( <parameter>value</parameter> <type>anycompatible</type>
21857 <optional>, <parameter>offset</parameter> <type>integer</type>
21858 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
21859 <returnvalue>anycompatible</returnvalue>
21860 </para>
21861 <para>
21862 Returns <parameter>value</parameter> evaluated at
21863 the row that is <parameter>offset</parameter>
21864 rows before the current row within the partition; if there is no such
21865 row, instead returns <parameter>default</parameter>
21866 (which must be of a type compatible with
21867 <parameter>value</parameter>).
21868 Both <parameter>offset</parameter> and
21869 <parameter>default</parameter> are evaluated
21870 with respect to the current row. If omitted,
21871 <parameter>offset</parameter> defaults to 1 and
21872 <parameter>default</parameter> to <literal>NULL</literal>.
21873 </para></entry>
21874 </row>
21876 <row>
21877 <entry role="func_table_entry"><para role="func_signature">
21878 <indexterm>
21879 <primary>lead</primary>
21880 </indexterm>
21881 <function>lead</function> ( <parameter>value</parameter> <type>anycompatible</type>
21882 <optional>, <parameter>offset</parameter> <type>integer</type>
21883 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
21884 <returnvalue>anycompatible</returnvalue>
21885 </para>
21886 <para>
21887 Returns <parameter>value</parameter> evaluated at
21888 the row that is <parameter>offset</parameter>
21889 rows after the current row within the partition; if there is no such
21890 row, instead returns <parameter>default</parameter>
21891 (which must be of a type compatible with
21892 <parameter>value</parameter>).
21893 Both <parameter>offset</parameter> and
21894 <parameter>default</parameter> are evaluated
21895 with respect to the current row. If omitted,
21896 <parameter>offset</parameter> defaults to 1 and
21897 <parameter>default</parameter> to <literal>NULL</literal>.
21898 </para></entry>
21899 </row>
21901 <row>
21902 <entry role="func_table_entry"><para role="func_signature">
21903 <indexterm>
21904 <primary>first_value</primary>
21905 </indexterm>
21906 <function>first_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
21907 <returnvalue>anyelement</returnvalue>
21908 </para>
21909 <para>
21910 Returns <parameter>value</parameter> evaluated
21911 at the row that is the first row of the window frame.
21912 </para></entry>
21913 </row>
21915 <row>
21916 <entry role="func_table_entry"><para role="func_signature">
21917 <indexterm>
21918 <primary>last_value</primary>
21919 </indexterm>
21920 <function>last_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
21921 <returnvalue>anyelement</returnvalue>
21922 </para>
21923 <para>
21924 Returns <parameter>value</parameter> evaluated
21925 at the row that is the last row of the window frame.
21926 </para></entry>
21927 </row>
21929 <row>
21930 <entry role="func_table_entry"><para role="func_signature">
21931 <indexterm>
21932 <primary>nth_value</primary>
21933 </indexterm>
21934 <function>nth_value</function> ( <parameter>value</parameter> <type>anyelement</type>, <parameter>n</parameter> <type>integer</type> )
21935 <returnvalue>anyelement</returnvalue>
21936 </para>
21937 <para>
21938 Returns <parameter>value</parameter> evaluated
21939 at the row that is the <parameter>n</parameter>'th
21940 row of the window frame (counting from 1);
21941 returns <literal>NULL</literal> if there is no such row.
21942 </para></entry>
21943 </row>
21944 </tbody>
21945 </tgroup>
21946 </table>
21948 <para>
21949 All of the functions listed in
21950 <xref linkend="functions-window-table"/> depend on the sort ordering
21951 specified by the <literal>ORDER BY</literal> clause of the associated window
21952 definition. Rows that are not distinct when considering only the
21953 <literal>ORDER BY</literal> columns are said to be <firstterm>peers</firstterm>.
21954 The four ranking functions (including <function>cume_dist</function>) are
21955 defined so that they give the same answer for all rows of a peer group.
21956 </para>
21958 <para>
21959 Note that <function>first_value</function>, <function>last_value</function>, and
21960 <function>nth_value</function> consider only the rows within the <quote>window
21961 frame</quote>, which by default contains the rows from the start of the
21962 partition through the last peer of the current row. This is
21963 likely to give unhelpful results for <function>last_value</function> and
21964 sometimes also <function>nth_value</function>. You can redefine the frame by
21965 adding a suitable frame specification (<literal>RANGE</literal>,
21966 <literal>ROWS</literal> or <literal>GROUPS</literal>) to
21967 the <literal>OVER</literal> clause.
21968 See <xref linkend="syntax-window-functions"/> for more information
21969 about frame specifications.
21970 </para>
21972 <para>
21973 When an aggregate function is used as a window function, it aggregates
21974 over the rows within the current row's window frame.
21975 An aggregate used with <literal>ORDER BY</literal> and the default window frame
21976 definition produces a <quote>running sum</quote> type of behavior, which may or
21977 may not be what's wanted. To obtain
21978 aggregation over the whole partition, omit <literal>ORDER BY</literal> or use
21979 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</literal>.
21980 Other frame specifications can be used to obtain other effects.
21981 </para>
21983 <note>
21984 <para>
21985 The SQL standard defines a <literal>RESPECT NULLS</literal> or
21986 <literal>IGNORE NULLS</literal> option for <function>lead</function>, <function>lag</function>,
21987 <function>first_value</function>, <function>last_value</function>, and
21988 <function>nth_value</function>. This is not implemented in
21989 <productname>PostgreSQL</productname>: the behavior is always the
21990 same as the standard's default, namely <literal>RESPECT NULLS</literal>.
21991 Likewise, the standard's <literal>FROM FIRST</literal> or <literal>FROM LAST</literal>
21992 option for <function>nth_value</function> is not implemented: only the
21993 default <literal>FROM FIRST</literal> behavior is supported. (You can achieve
21994 the result of <literal>FROM LAST</literal> by reversing the <literal>ORDER BY</literal>
21995 ordering.)
21996 </para>
21997 </note>
21999 </sect1>
22001 <sect1 id="functions-subquery">
22002 <title>Subquery Expressions</title>
22004 <indexterm>
22005 <primary>EXISTS</primary>
22006 </indexterm>
22008 <indexterm>
22009 <primary>IN</primary>
22010 </indexterm>
22012 <indexterm>
22013 <primary>NOT IN</primary>
22014 </indexterm>
22016 <indexterm>
22017 <primary>ANY</primary>
22018 </indexterm>
22020 <indexterm>
22021 <primary>ALL</primary>
22022 </indexterm>
22024 <indexterm>
22025 <primary>SOME</primary>
22026 </indexterm>
22028 <indexterm>
22029 <primary>subquery</primary>
22030 </indexterm>
22032 <para>
22033 This section describes the <acronym>SQL</acronym>-compliant subquery
22034 expressions available in <productname>PostgreSQL</productname>.
22035 All of the expression forms documented in this section return
22036 Boolean (true/false) results.
22037 </para>
22039 <sect2 id="functions-subquery-exists">
22040 <title><literal>EXISTS</literal></title>
22042 <synopsis>
22043 EXISTS (<replaceable>subquery</replaceable>)
22044 </synopsis>
22046 <para>
22047 The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</command> statement,
22048 or <firstterm>subquery</firstterm>. The
22049 subquery is evaluated to determine whether it returns any rows.
22050 If it returns at least one row, the result of <token>EXISTS</token> is
22051 <quote>true</quote>; if the subquery returns no rows, the result of <token>EXISTS</token>
22052 is <quote>false</quote>.
22053 </para>
22055 <para>
22056 The subquery can refer to variables from the surrounding query,
22057 which will act as constants during any one evaluation of the subquery.
22058 </para>
22060 <para>
22061 The subquery will generally only be executed long enough to determine
22062 whether at least one row is returned, not all the way to completion.
22063 It is unwise to write a subquery that has side effects (such as
22064 calling sequence functions); whether the side effects occur
22065 might be unpredictable.
22066 </para>
22068 <para>
22069 Since the result depends only on whether any rows are returned,
22070 and not on the contents of those rows, the output list of the
22071 subquery is normally unimportant. A common coding convention is
22072 to write all <literal>EXISTS</literal> tests in the form
22073 <literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
22074 this rule however, such as subqueries that use <token>INTERSECT</token>.
22075 </para>
22077 <para>
22078 This simple example is like an inner join on <literal>col2</literal>, but
22079 it produces at most one output row for each <literal>tab1</literal> row,
22080 even if there are several matching <literal>tab2</literal> rows:
22081 <screen>
22082 SELECT col1
22083 FROM tab1
22084 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
22085 </screen>
22086 </para>
22087 </sect2>
22089 <sect2 id="functions-subquery-in">
22090 <title><literal>IN</literal></title>
22092 <synopsis>
22093 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
22094 </synopsis>
22096 <para>
22097 The right-hand side is a parenthesized
22098 subquery, which must return exactly one column. The left-hand expression
22099 is evaluated and compared to each row of the subquery result.
22100 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
22101 The result is <quote>false</quote> if no equal row is found (including the
22102 case where the subquery returns no rows).
22103 </para>
22105 <para>
22106 Note that if the left-hand expression yields null, or if there are
22107 no equal right-hand values and at least one right-hand row yields
22108 null, the result of the <token>IN</token> construct will be null, not false.
22109 This is in accordance with SQL's normal rules for Boolean combinations
22110 of null values.
22111 </para>
22113 <para>
22114 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22115 be evaluated completely.
22116 </para>
22118 <synopsis>
22119 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
22120 </synopsis>
22122 <para>
22123 The left-hand side of this form of <token>IN</token> is a row constructor,
22124 as described in <xref linkend="sql-syntax-row-constructors"/>.
22125 The right-hand side is a parenthesized
22126 subquery, which must return exactly as many columns as there are
22127 expressions in the left-hand row. The left-hand expressions are
22128 evaluated and compared row-wise to each row of the subquery result.
22129 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
22130 The result is <quote>false</quote> if no equal row is found (including the
22131 case where the subquery returns no rows).
22132 </para>
22134 <para>
22135 As usual, null values in the rows are combined per
22136 the normal rules of SQL Boolean expressions. Two rows are considered
22137 equal if all their corresponding members are non-null and equal; the rows
22138 are unequal if any corresponding members are non-null and unequal;
22139 otherwise the result of that row comparison is unknown (null).
22140 If all the per-row results are either unequal or null, with at least one
22141 null, then the result of <token>IN</token> is null.
22142 </para>
22143 </sect2>
22145 <sect2 id="functions-subquery-notin">
22146 <title><literal>NOT IN</literal></title>
22148 <synopsis>
22149 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
22150 </synopsis>
22152 <para>
22153 The right-hand side is a parenthesized
22154 subquery, which must return exactly one column. The left-hand expression
22155 is evaluated and compared to each row of the subquery result.
22156 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
22157 are found (including the case where the subquery returns no rows).
22158 The result is <quote>false</quote> if any equal row is found.
22159 </para>
22161 <para>
22162 Note that if the left-hand expression yields null, or if there are
22163 no equal right-hand values and at least one right-hand row yields
22164 null, the result of the <token>NOT IN</token> construct will be null, not true.
22165 This is in accordance with SQL's normal rules for Boolean combinations
22166 of null values.
22167 </para>
22169 <para>
22170 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22171 be evaluated completely.
22172 </para>
22174 <synopsis>
22175 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
22176 </synopsis>
22178 <para>
22179 The left-hand side of this form of <token>NOT IN</token> is a row constructor,
22180 as described in <xref linkend="sql-syntax-row-constructors"/>.
22181 The right-hand side is a parenthesized
22182 subquery, which must return exactly as many columns as there are
22183 expressions in the left-hand row. The left-hand expressions are
22184 evaluated and compared row-wise to each row of the subquery result.
22185 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
22186 are found (including the case where the subquery returns no rows).
22187 The result is <quote>false</quote> if any equal row is found.
22188 </para>
22190 <para>
22191 As usual, null values in the rows are combined per
22192 the normal rules of SQL Boolean expressions. Two rows are considered
22193 equal if all their corresponding members are non-null and equal; the rows
22194 are unequal if any corresponding members are non-null and unequal;
22195 otherwise the result of that row comparison is unknown (null).
22196 If all the per-row results are either unequal or null, with at least one
22197 null, then the result of <token>NOT IN</token> is null.
22198 </para>
22199 </sect2>
22201 <sect2 id="functions-subquery-any-some">
22202 <title><literal>ANY</literal>/<literal>SOME</literal></title>
22204 <synopsis>
22205 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
22206 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
22207 </synopsis>
22209 <para>
22210 The right-hand side is a parenthesized
22211 subquery, which must return exactly one column. The left-hand expression
22212 is evaluated and compared to each row of the subquery result using the
22213 given <replaceable>operator</replaceable>, which must yield a Boolean
22214 result.
22215 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
22216 The result is <quote>false</quote> if no true result is found (including the
22217 case where the subquery returns no rows).
22218 </para>
22220 <para>
22221 <token>SOME</token> is a synonym for <token>ANY</token>.
22222 <token>IN</token> is equivalent to <literal>= ANY</literal>.
22223 </para>
22225 <para>
22226 Note that if there are no successes and at least one right-hand row yields
22227 null for the operator's result, the result of the <token>ANY</token> construct
22228 will be null, not false.
22229 This is in accordance with SQL's normal rules for Boolean combinations
22230 of null values.
22231 </para>
22233 <para>
22234 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22235 be evaluated completely.
22236 </para>
22238 <synopsis>
22239 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
22240 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
22241 </synopsis>
22243 <para>
22244 The left-hand side of this form of <token>ANY</token> is a row constructor,
22245 as described in <xref linkend="sql-syntax-row-constructors"/>.
22246 The right-hand side is a parenthesized
22247 subquery, which must return exactly as many columns as there are
22248 expressions in the left-hand row. The left-hand expressions are
22249 evaluated and compared row-wise to each row of the subquery result,
22250 using the given <replaceable>operator</replaceable>.
22251 The result of <token>ANY</token> is <quote>true</quote> if the comparison
22252 returns true for any subquery row.
22253 The result is <quote>false</quote> if the comparison returns false for every
22254 subquery row (including the case where the subquery returns no
22255 rows).
22256 The result is NULL if no comparison with a subquery row returns true,
22257 and at least one comparison returns NULL.
22258 </para>
22260 <para>
22261 See <xref linkend="row-wise-comparison"/> for details about the meaning
22262 of a row constructor comparison.
22263 </para>
22264 </sect2>
22266 <sect2 id="functions-subquery-all">
22267 <title><literal>ALL</literal></title>
22269 <synopsis>
22270 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
22271 </synopsis>
22273 <para>
22274 The right-hand side is a parenthesized
22275 subquery, which must return exactly one column. The left-hand expression
22276 is evaluated and compared to each row of the subquery result using the
22277 given <replaceable>operator</replaceable>, which must yield a Boolean
22278 result.
22279 The result of <token>ALL</token> is <quote>true</quote> if all rows yield true
22280 (including the case where the subquery returns no rows).
22281 The result is <quote>false</quote> if any false result is found.
22282 The result is NULL if no comparison with a subquery row returns false,
22283 and at least one comparison returns NULL.
22284 </para>
22286 <para>
22287 <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
22288 </para>
22290 <para>
22291 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22292 be evaluated completely.
22293 </para>
22295 <synopsis>
22296 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
22297 </synopsis>
22299 <para>
22300 The left-hand side of this form of <token>ALL</token> is a row constructor,
22301 as described in <xref linkend="sql-syntax-row-constructors"/>.
22302 The right-hand side is a parenthesized
22303 subquery, which must return exactly as many columns as there are
22304 expressions in the left-hand row. The left-hand expressions are
22305 evaluated and compared row-wise to each row of the subquery result,
22306 using the given <replaceable>operator</replaceable>.
22307 The result of <token>ALL</token> is <quote>true</quote> if the comparison
22308 returns true for all subquery rows (including the
22309 case where the subquery returns no rows).
22310 The result is <quote>false</quote> if the comparison returns false for any
22311 subquery row.
22312 The result is NULL if no comparison with a subquery row returns false,
22313 and at least one comparison returns NULL.
22314 </para>
22316 <para>
22317 See <xref linkend="row-wise-comparison"/> for details about the meaning
22318 of a row constructor comparison.
22319 </para>
22320 </sect2>
22322 <sect2 id="functions-subquery-single-row-comp">
22323 <title>Single-Row Comparison</title>
22325 <indexterm zone="functions-subquery">
22326 <primary>comparison</primary>
22327 <secondary>subquery result row</secondary>
22328 </indexterm>
22330 <synopsis>
22331 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
22332 </synopsis>
22334 <para>
22335 The left-hand side is a row constructor,
22336 as described in <xref linkend="sql-syntax-row-constructors"/>.
22337 The right-hand side is a parenthesized subquery, which must return exactly
22338 as many columns as there are expressions in the left-hand row. Furthermore,
22339 the subquery cannot return more than one row. (If it returns zero rows,
22340 the result is taken to be null.) The left-hand side is evaluated and
22341 compared row-wise to the single subquery result row.
22342 </para>
22344 <para>
22345 See <xref linkend="row-wise-comparison"/> for details about the meaning
22346 of a row constructor comparison.
22347 </para>
22348 </sect2>
22349 </sect1>
22352 <sect1 id="functions-comparisons">
22353 <title>Row and Array Comparisons</title>
22355 <indexterm>
22356 <primary>IN</primary>
22357 </indexterm>
22359 <indexterm>
22360 <primary>NOT IN</primary>
22361 </indexterm>
22363 <indexterm>
22364 <primary>ANY</primary>
22365 </indexterm>
22367 <indexterm>
22368 <primary>ALL</primary>
22369 </indexterm>
22371 <indexterm>
22372 <primary>SOME</primary>
22373 </indexterm>
22375 <indexterm>
22376 <primary>composite type</primary>
22377 <secondary>comparison</secondary>
22378 </indexterm>
22380 <indexterm>
22381 <primary>row-wise comparison</primary>
22382 </indexterm>
22384 <indexterm>
22385 <primary>comparison</primary>
22386 <secondary>composite type</secondary>
22387 </indexterm>
22389 <indexterm>
22390 <primary>comparison</primary>
22391 <secondary>row constructor</secondary>
22392 </indexterm>
22394 <indexterm>
22395 <primary>IS DISTINCT FROM</primary>
22396 </indexterm>
22398 <indexterm>
22399 <primary>IS NOT DISTINCT FROM</primary>
22400 </indexterm>
22402 <para>
22403 This section describes several specialized constructs for making
22404 multiple comparisons between groups of values. These forms are
22405 syntactically related to the subquery forms of the previous section,
22406 but do not involve subqueries.
22407 The forms involving array subexpressions are
22408 <productname>PostgreSQL</productname> extensions; the rest are
22409 <acronym>SQL</acronym>-compliant.
22410 All of the expression forms documented in this section return
22411 Boolean (true/false) results.
22412 </para>
22414 <sect2 id="functions-comparisons-in-scalar">
22415 <title><literal>IN</literal></title>
22417 <synopsis>
22418 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
22419 </synopsis>
22421 <para>
22422 The right-hand side is a parenthesized list
22423 of expressions. The result is <quote>true</quote> if the left-hand expression's
22424 result is equal to any of the right-hand expressions. This is a shorthand
22425 notation for
22427 <synopsis>
22428 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
22430 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
22433 </synopsis>
22434 </para>
22436 <para>
22437 Note that if the left-hand expression yields null, or if there are
22438 no equal right-hand values and at least one right-hand expression yields
22439 null, the result of the <token>IN</token> construct will be null, not false.
22440 This is in accordance with SQL's normal rules for Boolean combinations
22441 of null values.
22442 </para>
22443 </sect2>
22445 <sect2 id="functions-comparisons-not-in">
22446 <title><literal>NOT IN</literal></title>
22448 <synopsis>
22449 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
22450 </synopsis>
22452 <para>
22453 The right-hand side is a parenthesized list
22454 of expressions. The result is <quote>true</quote> if the left-hand expression's
22455 result is unequal to all of the right-hand expressions. This is a shorthand
22456 notation for
22458 <synopsis>
22459 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
22461 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
22464 </synopsis>
22465 </para>
22467 <para>
22468 Note that if the left-hand expression yields null, or if there are
22469 no equal right-hand values and at least one right-hand expression yields
22470 null, the result of the <token>NOT IN</token> construct will be null, not true
22471 as one might naively expect.
22472 This is in accordance with SQL's normal rules for Boolean combinations
22473 of null values.
22474 </para>
22476 <tip>
22477 <para>
22478 <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
22479 cases. However, null values are much more likely to trip up the novice when
22480 working with <token>NOT IN</token> than when working with <token>IN</token>.
22481 It is best to express your condition positively if possible.
22482 </para>
22483 </tip>
22484 </sect2>
22486 <sect2 id="functions-comparisons-any-some">
22487 <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
22489 <synopsis>
22490 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
22491 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
22492 </synopsis>
22494 <para>
22495 The right-hand side is a parenthesized expression, which must yield an
22496 array value.
22497 The left-hand expression
22498 is evaluated and compared to each element of the array using the
22499 given <replaceable>operator</replaceable>, which must yield a Boolean
22500 result.
22501 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
22502 The result is <quote>false</quote> if no true result is found (including the
22503 case where the array has zero elements).
22504 </para>
22506 <para>
22507 If the array expression yields a null array, the result of
22508 <token>ANY</token> will be null. If the left-hand expression yields null,
22509 the result of <token>ANY</token> is ordinarily null (though a non-strict
22510 comparison operator could possibly yield a different result).
22511 Also, if the right-hand array contains any null elements and no true
22512 comparison result is obtained, the result of <token>ANY</token>
22513 will be null, not false (again, assuming a strict comparison operator).
22514 This is in accordance with SQL's normal rules for Boolean combinations
22515 of null values.
22516 </para>
22518 <para>
22519 <token>SOME</token> is a synonym for <token>ANY</token>.
22520 </para>
22521 </sect2>
22523 <sect2 id="functions-comparisons-all">
22524 <title><literal>ALL</literal> (array)</title>
22526 <synopsis>
22527 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
22528 </synopsis>
22530 <para>
22531 The right-hand side is a parenthesized expression, which must yield an
22532 array value.
22533 The left-hand expression
22534 is evaluated and compared to each element of the array using the
22535 given <replaceable>operator</replaceable>, which must yield a Boolean
22536 result.
22537 The result of <token>ALL</token> is <quote>true</quote> if all comparisons yield true
22538 (including the case where the array has zero elements).
22539 The result is <quote>false</quote> if any false result is found.
22540 </para>
22542 <para>
22543 If the array expression yields a null array, the result of
22544 <token>ALL</token> will be null. If the left-hand expression yields null,
22545 the result of <token>ALL</token> is ordinarily null (though a non-strict
22546 comparison operator could possibly yield a different result).
22547 Also, if the right-hand array contains any null elements and no false
22548 comparison result is obtained, the result of <token>ALL</token>
22549 will be null, not true (again, assuming a strict comparison operator).
22550 This is in accordance with SQL's normal rules for Boolean combinations
22551 of null values.
22552 </para>
22553 </sect2>
22555 <sect2 id="row-wise-comparison">
22556 <title>Row Constructor Comparison</title>
22558 <synopsis>
22559 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
22560 </synopsis>
22562 <para>
22563 Each side is a row constructor,
22564 as described in <xref linkend="sql-syntax-row-constructors"/>.
22565 The two row constructors must have the same number of fields.
22566 The given <replaceable>operator</replaceable> is applied to each pair
22567 of corresponding fields. (Since the fields could be of different
22568 types, this means that a different specific operator could be selected
22569 for each pair.)
22570 All the selected operators must be members of some B-tree operator
22571 class, or be the negator of an <literal>=</literal> member of a B-tree
22572 operator class, meaning that row constructor comparison is only
22573 possible when the <replaceable>operator</replaceable> is
22574 <literal>=</literal>,
22575 <literal>&lt;&gt;</literal>,
22576 <literal>&lt;</literal>,
22577 <literal>&lt;=</literal>,
22578 <literal>&gt;</literal>, or
22579 <literal>&gt;=</literal>,
22580 or has semantics similar to one of these.
22581 </para>
22583 <para>
22584 The <literal>=</literal> and <literal>&lt;&gt;</literal> cases work slightly differently
22585 from the others. Two rows are considered
22586 equal if all their corresponding members are non-null and equal; the rows
22587 are unequal if any corresponding members are non-null and unequal;
22588 otherwise the result of the row comparison is unknown (null).
22589 </para>
22591 <para>
22592 For the <literal>&lt;</literal>, <literal>&lt;=</literal>, <literal>&gt;</literal> and
22593 <literal>&gt;=</literal> cases, the row elements are compared left-to-right,
22594 stopping as soon as an unequal or null pair of elements is found.
22595 If either of this pair of elements is null, the result of the
22596 row comparison is unknown (null); otherwise comparison of this pair
22597 of elements determines the result. For example,
22598 <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</literal>
22599 yields true, not null, because the third pair of elements are not
22600 considered.
22601 </para>
22603 <synopsis>
22604 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
22605 </synopsis>
22607 <para>
22608 This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
22609 but it does not yield null for null inputs. Instead, any null value is
22610 considered unequal to (distinct from) any non-null value, and any two
22611 nulls are considered equal (not distinct). Thus the result will
22612 either be true or false, never null.
22613 </para>
22615 <synopsis>
22616 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
22617 </synopsis>
22619 <para>
22620 This construct is similar to a <literal>=</literal> row comparison,
22621 but it does not yield null for null inputs. Instead, any null value is
22622 considered unequal to (distinct from) any non-null value, and any two
22623 nulls are considered equal (not distinct). Thus the result will always
22624 be either true or false, never null.
22625 </para>
22627 </sect2>
22629 <sect2 id="composite-type-comparison">
22630 <title>Composite Type Comparison</title>
22632 <synopsis>
22633 <replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
22634 </synopsis>
22636 <para>
22637 The SQL specification requires row-wise comparison to return NULL if the
22638 result depends on comparing two NULL values or a NULL and a non-NULL.
22639 <productname>PostgreSQL</productname> does this only when comparing the
22640 results of two row constructors (as in
22641 <xref linkend="row-wise-comparison"/>) or comparing a row constructor
22642 to the output of a subquery (as in <xref linkend="functions-subquery"/>).
22643 In other contexts where two composite-type values are compared, two
22644 NULL field values are considered equal, and a NULL is considered larger
22645 than a non-NULL. This is necessary in order to have consistent sorting
22646 and indexing behavior for composite types.
22647 </para>
22649 <para>
22650 Each side is evaluated and they are compared row-wise. Composite type
22651 comparisons are allowed when the <replaceable>operator</replaceable> is
22652 <literal>=</literal>,
22653 <literal>&lt;&gt;</literal>,
22654 <literal>&lt;</literal>,
22655 <literal>&lt;=</literal>,
22656 <literal>&gt;</literal> or
22657 <literal>&gt;=</literal>,
22658 or has semantics similar to one of these. (To be specific, an operator
22659 can be a row comparison operator if it is a member of a B-tree operator
22660 class, or is the negator of the <literal>=</literal> member of a B-tree operator
22661 class.) The default behavior of the above operators is the same as for
22662 <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
22663 <xref linkend="row-wise-comparison"/>).
22664 </para>
22666 <para>
22667 To support matching of rows which include elements without a default
22668 B-tree operator class, the following operators are defined for composite
22669 type comparison:
22670 <literal>*=</literal>,
22671 <literal>*&lt;&gt;</literal>,
22672 <literal>*&lt;</literal>,
22673 <literal>*&lt;=</literal>,
22674 <literal>*&gt;</literal>, and
22675 <literal>*&gt;=</literal>.
22676 These operators compare the internal binary representation of the two
22677 rows. Two rows might have a different binary representation even
22678 though comparisons of the two rows with the equality operator is true.
22679 The ordering of rows under these comparison operators is deterministic
22680 but not otherwise meaningful. These operators are used internally
22681 for materialized views and might be useful for other specialized
22682 purposes such as replication and B-Tree deduplication (see <xref
22683 linkend="btree-deduplication"/>). They are not intended to be
22684 generally useful for writing queries, though.
22685 </para>
22686 </sect2>
22687 </sect1>
22689 <sect1 id="functions-srf">
22690 <title>Set Returning Functions</title>
22692 <indexterm zone="functions-srf">
22693 <primary>set returning functions</primary>
22694 <secondary>functions</secondary>
22695 </indexterm>
22697 <para>
22698 This section describes functions that possibly return more than one row.
22699 The most widely used functions in this class are series generating
22700 functions, as detailed in <xref linkend="functions-srf-series"/> and
22701 <xref linkend="functions-srf-subscripts"/>. Other, more specialized
22702 set-returning functions are described elsewhere in this manual.
22703 See <xref linkend="queries-tablefunctions"/> for ways to combine multiple
22704 set-returning functions.
22705 </para>
22707 <table id="functions-srf-series">
22708 <title>Series Generating Functions</title>
22709 <tgroup cols="1">
22710 <thead>
22711 <row>
22712 <entry role="func_table_entry"><para role="func_signature">
22713 Function
22714 </para>
22715 <para>
22716 Description
22717 </para></entry>
22718 </row>
22719 </thead>
22721 <tbody>
22722 <row>
22723 <entry role="func_table_entry"><para role="func_signature">
22724 <indexterm>
22725 <primary>generate_series</primary>
22726 </indexterm>
22727 <function>generate_series</function> ( <parameter>start</parameter> <type>integer</type>, <parameter>stop</parameter> <type>integer</type> <optional>, <parameter>step</parameter> <type>integer</type> </optional> )
22728 <returnvalue>setof integer</returnvalue>
22729 </para>
22730 <para role="func_signature">
22731 <function>generate_series</function> ( <parameter>start</parameter> <type>bigint</type>, <parameter>stop</parameter> <type>bigint</type> <optional>, <parameter>step</parameter> <type>bigint</type> </optional> )
22732 <returnvalue>setof bigint</returnvalue>
22733 </para>
22734 <para role="func_signature">
22735 <function>generate_series</function> ( <parameter>start</parameter> <type>numeric</type>, <parameter>stop</parameter> <type>numeric</type> <optional>, <parameter>step</parameter> <type>numeric</type> </optional> )
22736 <returnvalue>setof numeric</returnvalue>
22737 </para>
22738 <para>
22739 Generates a series of values from <parameter>start</parameter>
22740 to <parameter>stop</parameter>, with a step size
22741 of <parameter>step</parameter>. <parameter>step</parameter>
22742 defaults to 1.
22743 </para></entry>
22744 </row>
22746 <row>
22747 <entry role="func_table_entry"><para role="func_signature">
22748 <function>generate_series</function> ( <parameter>start</parameter> <type>timestamp</type>, <parameter>stop</parameter> <type>timestamp</type>, <parameter>step</parameter> <type>interval</type> )
22749 <returnvalue>setof timestamp</returnvalue>
22750 </para>
22751 <para role="func_signature">
22752 <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> )
22753 <returnvalue>setof timestamp with time zone</returnvalue>
22754 </para>
22755 <para>
22756 Generates a series of values from <parameter>start</parameter>
22757 to <parameter>stop</parameter>, with a step size
22758 of <parameter>step</parameter>.
22759 In the timezone-aware form, times of day and daylight-savings
22760 adjustments are computed according to the time zone named by
22761 the <parameter>timezone</parameter> argument, or the current
22762 <xref linkend="guc-timezone"/> setting if that is omitted.
22763 </para></entry>
22764 </row>
22765 </tbody>
22766 </tgroup>
22767 </table>
22769 <para>
22770 When <parameter>step</parameter> is positive, zero rows are returned if
22771 <parameter>start</parameter> is greater than <parameter>stop</parameter>.
22772 Conversely, when <parameter>step</parameter> is negative, zero rows are
22773 returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
22774 Zero rows are also returned if any input is <literal>NULL</literal>.
22775 It is an error
22776 for <parameter>step</parameter> to be zero. Some examples follow:
22777 <programlisting>
22778 SELECT * FROM generate_series(2,4);
22779 generate_series
22780 -----------------
22784 (3 rows)
22786 SELECT * FROM generate_series(5,1,-2);
22787 generate_series
22788 -----------------
22792 (3 rows)
22794 SELECT * FROM generate_series(4,3);
22795 generate_series
22796 -----------------
22797 (0 rows)
22799 SELECT generate_series(1.1, 4, 1.3);
22800 generate_series
22801 -----------------
22805 (3 rows)
22807 -- this example relies on the date-plus-integer operator:
22808 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
22809 dates
22810 ------------
22811 2004-02-05
22812 2004-02-12
22813 2004-02-19
22814 (3 rows)
22816 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
22817 '2008-03-04 12:00', '10 hours');
22818 generate_series
22819 ---------------------
22820 2008-03-01 00:00:00
22821 2008-03-01 10:00:00
22822 2008-03-01 20:00:00
22823 2008-03-02 06:00:00
22824 2008-03-02 16:00:00
22825 2008-03-03 02:00:00
22826 2008-03-03 12:00:00
22827 2008-03-03 22:00:00
22828 2008-03-04 08:00:00
22829 (9 rows)
22831 -- this example assumes that TimeZone is set to UTC; note the DST transition:
22832 SELECT * FROM generate_series('2001-10-22 00:00 -04:00'::timestamptz,
22833 '2001-11-01 00:00 -05:00'::timestamptz,
22834 '1 day'::interval, 'America/New_York');
22835 generate_series
22836 ------------------------
22837 2001-10-22 04:00:00+00
22838 2001-10-23 04:00:00+00
22839 2001-10-24 04:00:00+00
22840 2001-10-25 04:00:00+00
22841 2001-10-26 04:00:00+00
22842 2001-10-27 04:00:00+00
22843 2001-10-28 04:00:00+00
22844 2001-10-29 05:00:00+00
22845 2001-10-30 05:00:00+00
22846 2001-10-31 05:00:00+00
22847 2001-11-01 05:00:00+00
22848 (11 rows)
22849 </programlisting>
22850 </para>
22852 <table id="functions-srf-subscripts">
22853 <title>Subscript Generating Functions</title>
22854 <tgroup cols="1">
22855 <thead>
22856 <row>
22857 <entry role="func_table_entry"><para role="func_signature">
22858 Function
22859 </para>
22860 <para>
22861 Description
22862 </para></entry>
22863 </row>
22864 </thead>
22866 <tbody>
22867 <row>
22868 <entry role="func_table_entry"><para role="func_signature">
22869 <indexterm>
22870 <primary>generate_subscripts</primary>
22871 </indexterm>
22872 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type> )
22873 <returnvalue>setof integer</returnvalue>
22874 </para>
22875 <para>
22876 Generates a series comprising the valid subscripts of
22877 the <parameter>dim</parameter>'th dimension of the given array.
22878 </para></entry>
22879 </row>
22881 <row>
22882 <entry role="func_table_entry"><para role="func_signature">
22883 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type>, <parameter>reverse</parameter> <type>boolean</type> )
22884 <returnvalue>setof integer</returnvalue>
22885 </para>
22886 <para>
22887 Generates a series comprising the valid subscripts of
22888 the <parameter>dim</parameter>'th dimension of the given array.
22889 When <parameter>reverse</parameter> is true, returns the series in
22890 reverse order.
22891 </para></entry>
22892 </row>
22893 </tbody>
22894 </tgroup>
22895 </table>
22897 <para>
22898 <function>generate_subscripts</function> is a convenience function that generates
22899 the set of valid subscripts for the specified dimension of the given
22900 array.
22901 Zero rows are returned for arrays that do not have the requested dimension,
22902 or if any input is <literal>NULL</literal>.
22903 Some examples follow:
22904 <programlisting>
22905 -- basic usage:
22906 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
22913 (4 rows)
22915 -- presenting an array, the subscript and the subscripted
22916 -- value requires a subquery:
22917 SELECT * FROM arrays;
22919 --------------------
22920 {-1,-2}
22921 {100,200,300}
22922 (2 rows)
22924 SELECT a AS array, s AS subscript, a[s] AS value
22925 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
22926 array | subscript | value
22927 ---------------+-----------+-------
22928 {-1,-2} | 1 | -1
22929 {-1,-2} | 2 | -2
22930 {100,200,300} | 1 | 100
22931 {100,200,300} | 2 | 200
22932 {100,200,300} | 3 | 300
22933 (5 rows)
22935 -- unnest a 2D array:
22936 CREATE OR REPLACE FUNCTION unnest2(anyarray)
22937 RETURNS SETOF anyelement AS $$
22938 select $1[i][j]
22939 from generate_subscripts($1,1) g1(i),
22940 generate_subscripts($1,2) g2(j);
22941 $$ LANGUAGE sql IMMUTABLE;
22942 CREATE FUNCTION
22943 SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
22944 unnest2
22945 ---------
22950 (4 rows)
22951 </programlisting>
22952 </para>
22954 <indexterm>
22955 <primary>ordinality</primary>
22956 </indexterm>
22958 <para>
22959 When a function in the <literal>FROM</literal> clause is suffixed
22960 by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is
22961 appended to the function's output column(s), which starts from 1 and
22962 increments by 1 for each row of the function's output.
22963 This is most useful in the case of set returning
22964 functions such as <function>unnest()</function>.
22966 <programlisting>
22967 -- set returning function WITH ORDINALITY:
22968 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
22969 ls | n
22970 -----------------+----
22971 pg_serial | 1
22972 pg_twophase | 2
22973 postmaster.opts | 3
22974 pg_notify | 4
22975 postgresql.conf | 5
22976 pg_tblspc | 6
22977 logfile | 7
22978 base | 8
22979 postmaster.pid | 9
22980 pg_ident.conf | 10
22981 global | 11
22982 pg_xact | 12
22983 pg_snapshots | 13
22984 pg_multixact | 14
22985 PG_VERSION | 15
22986 pg_wal | 16
22987 pg_hba.conf | 17
22988 pg_stat_tmp | 18
22989 pg_subtrans | 19
22990 (19 rows)
22991 </programlisting>
22992 </para>
22994 </sect1>
22996 <sect1 id="functions-info">
22997 <title>System Information Functions and Operators</title>
22999 <para>
23000 The functions described in this section are used to obtain various
23001 information about a <productname>PostgreSQL</productname> installation.
23002 </para>
23004 <sect2 id="functions-info-session">
23005 <title>Session Information Functions</title>
23007 <para>
23008 <xref linkend="functions-info-session-table"/> shows several
23009 functions that extract session and system information.
23010 </para>
23012 <para>
23013 In addition to the functions listed in this section, there are a number of
23014 functions related to the statistics system that also provide system
23015 information. See <xref linkend="monitoring-stats-functions"/> for more
23016 information.
23017 </para>
23019 <table id="functions-info-session-table">
23020 <title>Session Information Functions</title>
23021 <tgroup cols="1">
23022 <thead>
23023 <row>
23024 <entry role="func_table_entry"><para role="func_signature">
23025 Function
23026 </para>
23027 <para>
23028 Description
23029 </para></entry>
23030 </row>
23031 </thead>
23033 <tbody>
23034 <row>
23035 <entry role="func_table_entry"><para role="func_signature">
23036 <indexterm>
23037 <primary>current_catalog</primary>
23038 </indexterm>
23039 <function>current_catalog</function>
23040 <returnvalue>name</returnvalue>
23041 </para>
23042 <para role="func_signature">
23043 <indexterm>
23044 <primary>current_database</primary>
23045 </indexterm>
23046 <function>current_database</function> ()
23047 <returnvalue>name</returnvalue>
23048 </para>
23049 <para>
23050 Returns the name of the current database. (Databases are
23051 called <quote>catalogs</quote> in the SQL standard,
23052 so <function>current_catalog</function> is the standard's
23053 spelling.)
23054 </para></entry>
23055 </row>
23057 <row>
23058 <entry role="func_table_entry"><para role="func_signature">
23059 <indexterm>
23060 <primary>current_query</primary>
23061 </indexterm>
23062 <function>current_query</function> ()
23063 <returnvalue>text</returnvalue>
23064 </para>
23065 <para>
23066 Returns the text of the currently executing query, as submitted
23067 by the client (which might contain more than one statement).
23068 </para></entry>
23069 </row>
23071 <row>
23072 <entry role="func_table_entry"><para role="func_signature">
23073 <indexterm>
23074 <primary>current_role</primary>
23075 </indexterm>
23076 <function>current_role</function>
23077 <returnvalue>name</returnvalue>
23078 </para>
23079 <para>
23080 This is equivalent to <function>current_user</function>.
23081 </para></entry>
23082 </row>
23084 <row>
23085 <entry role="func_table_entry"><para role="func_signature">
23086 <indexterm>
23087 <primary>current_schema</primary>
23088 </indexterm>
23089 <indexterm>
23090 <primary>schema</primary>
23091 <secondary>current</secondary>
23092 </indexterm>
23093 <function>current_schema</function>
23094 <returnvalue>name</returnvalue>
23095 </para>
23096 <para role="func_signature">
23097 <function>current_schema</function> ()
23098 <returnvalue>name</returnvalue>
23099 </para>
23100 <para>
23101 Returns the name of the schema that is first in the search path (or a
23102 null value if the search path is empty). This is the schema that will
23103 be used for any tables or other named objects that are created without
23104 specifying a target schema.
23105 </para></entry>
23106 </row>
23108 <row>
23109 <entry role="func_table_entry"><para role="func_signature">
23110 <indexterm>
23111 <primary>current_schemas</primary>
23112 </indexterm>
23113 <indexterm>
23114 <primary>search path</primary>
23115 <secondary>current</secondary>
23116 </indexterm>
23117 <function>current_schemas</function> ( <parameter>include_implicit</parameter> <type>boolean</type> )
23118 <returnvalue>name[]</returnvalue>
23119 </para>
23120 <para>
23121 Returns an array of the names of all schemas presently in the
23122 effective search path, in their priority order. (Items in the current
23123 <xref linkend="guc-search-path"/> setting that do not correspond to
23124 existing, searchable schemas are omitted.) If the Boolean argument
23125 is <literal>true</literal>, then implicitly-searched system schemas
23126 such as <literal>pg_catalog</literal> are included in the result.
23127 </para></entry>
23128 </row>
23130 <row>
23131 <entry role="func_table_entry"><para role="func_signature">
23132 <indexterm>
23133 <primary>current_user</primary>
23134 </indexterm>
23135 <indexterm>
23136 <primary>user</primary>
23137 <secondary>current</secondary>
23138 </indexterm>
23139 <function>current_user</function>
23140 <returnvalue>name</returnvalue>
23141 </para>
23142 <para>
23143 Returns the user name of the current execution context.
23144 </para></entry>
23145 </row>
23147 <row>
23148 <entry role="func_table_entry"><para role="func_signature">
23149 <indexterm>
23150 <primary>inet_client_addr</primary>
23151 </indexterm>
23152 <function>inet_client_addr</function> ()
23153 <returnvalue>inet</returnvalue>
23154 </para>
23155 <para>
23156 Returns the IP address of the current client,
23157 or <literal>NULL</literal> if the current connection is via a
23158 Unix-domain socket.
23159 </para></entry>
23160 </row>
23162 <row>
23163 <entry role="func_table_entry"><para role="func_signature">
23164 <indexterm>
23165 <primary>inet_client_port</primary>
23166 </indexterm>
23167 <function>inet_client_port</function> ()
23168 <returnvalue>integer</returnvalue>
23169 </para>
23170 <para>
23171 Returns the IP port number of the current client,
23172 or <literal>NULL</literal> if the current connection is via a
23173 Unix-domain socket.
23174 </para></entry>
23175 </row>
23177 <row>
23178 <entry role="func_table_entry"><para role="func_signature">
23179 <indexterm>
23180 <primary>inet_server_addr</primary>
23181 </indexterm>
23182 <function>inet_server_addr</function> ()
23183 <returnvalue>inet</returnvalue>
23184 </para>
23185 <para>
23186 Returns the IP address on which the server accepted the current
23187 connection,
23188 or <literal>NULL</literal> if the current connection is via a
23189 Unix-domain socket.
23190 </para></entry>
23191 </row>
23193 <row>
23194 <entry role="func_table_entry"><para role="func_signature">
23195 <indexterm>
23196 <primary>inet_server_port</primary>
23197 </indexterm>
23198 <function>inet_server_port</function> ()
23199 <returnvalue>integer</returnvalue>
23200 </para>
23201 <para>
23202 Returns the IP port number on which the server accepted the current
23203 connection,
23204 or <literal>NULL</literal> if the current connection is via a
23205 Unix-domain socket.
23206 </para></entry>
23207 </row>
23209 <row>
23210 <entry role="func_table_entry"><para role="func_signature">
23211 <indexterm>
23212 <primary>pg_backend_pid</primary>
23213 </indexterm>
23214 <function>pg_backend_pid</function> ()
23215 <returnvalue>integer</returnvalue>
23216 </para>
23217 <para>
23218 Returns the process ID of the server process attached to the current
23219 session.
23220 </para></entry>
23221 </row>
23223 <row>
23224 <entry role="func_table_entry"><para role="func_signature">
23225 <indexterm>
23226 <primary>pg_blocking_pids</primary>
23227 </indexterm>
23228 <function>pg_blocking_pids</function> ( <type>integer</type> )
23229 <returnvalue>integer[]</returnvalue>
23230 </para>
23231 <para>
23232 Returns an array of the process ID(s) of the sessions that are
23233 blocking the server process with the specified process ID from
23234 acquiring a lock, or an empty array if there is no such server process
23235 or it is not blocked.
23236 </para>
23237 <para>
23238 One server process blocks another if it either holds a lock that
23239 conflicts with the blocked process's lock request (hard block), or is
23240 waiting for a lock that would conflict with the blocked process's lock
23241 request and is ahead of it in the wait queue (soft block). When using
23242 parallel queries the result always lists client-visible process IDs
23243 (that is, <function>pg_backend_pid</function> results) even if the
23244 actual lock is held or awaited by a child worker process. As a result
23245 of that, there may be duplicated PIDs in the result. Also note that
23246 when a prepared transaction holds a conflicting lock, it will be
23247 represented by a zero process ID.
23248 </para>
23249 <para>
23250 Frequent calls to this function could have some impact on database
23251 performance, because it needs exclusive access to the lock manager's
23252 shared state for a short time.
23253 </para></entry>
23254 </row>
23256 <row>
23257 <entry role="func_table_entry"><para role="func_signature">
23258 <indexterm>
23259 <primary>pg_conf_load_time</primary>
23260 </indexterm>
23261 <function>pg_conf_load_time</function> ()
23262 <returnvalue>timestamp with time zone</returnvalue>
23263 </para>
23264 <para>
23265 Returns the time when the server configuration files were last loaded.
23266 If the current session was alive at the time, this will be the time
23267 when the session itself re-read the configuration files (so the
23268 reading will vary a little in different sessions). Otherwise it is
23269 the time when the postmaster process re-read the configuration files.
23270 </para></entry>
23271 </row>
23273 <row>
23274 <entry role="func_table_entry"><para role="func_signature">
23275 <indexterm>
23276 <primary>pg_current_logfile</primary>
23277 </indexterm>
23278 <indexterm>
23279 <primary>Logging</primary>
23280 <secondary>pg_current_logfile function</secondary>
23281 </indexterm>
23282 <indexterm>
23283 <primary>current_logfiles</primary>
23284 <secondary>and the pg_current_logfile function</secondary>
23285 </indexterm>
23286 <indexterm>
23287 <primary>Logging</primary>
23288 <secondary>current_logfiles file and the pg_current_logfile
23289 function</secondary>
23290 </indexterm>
23291 <function>pg_current_logfile</function> ( <optional> <type>text</type> </optional> )
23292 <returnvalue>text</returnvalue>
23293 </para>
23294 <para>
23295 Returns the path name of the log file currently in use by the logging
23296 collector. The path includes the <xref linkend="guc-log-directory"/>
23297 directory and the individual log file name. The result
23298 is <literal>NULL</literal> if the logging collector is disabled.
23299 When multiple log files exist, each in a different
23300 format, <function>pg_current_logfile</function> without an argument
23301 returns the path of the file having the first format found in the
23302 ordered list: <literal>stderr</literal>,
23303 <literal>csvlog</literal>, <literal>jsonlog</literal>.
23304 <literal>NULL</literal> is returned if no log file has any of these
23305 formats.
23306 To request information about a specific log file format, supply
23307 either <literal>csvlog</literal>, <literal>jsonlog</literal> or
23308 <literal>stderr</literal> as the
23309 value of the optional parameter. The result is <literal>NULL</literal>
23310 if the log format requested is not configured in
23311 <xref linkend="guc-log-destination"/>.
23312 The result reflects the contents of
23313 the <filename>current_logfiles</filename> file.
23314 </para></entry>
23315 </row>
23317 <row>
23318 <entry role="func_table_entry"><para role="func_signature">
23319 <indexterm>
23320 <primary>pg_my_temp_schema</primary>
23321 </indexterm>
23322 <function>pg_my_temp_schema</function> ()
23323 <returnvalue>oid</returnvalue>
23324 </para>
23325 <para>
23326 Returns the OID of the current session's temporary schema, or zero if
23327 it has none (because it has not created any temporary tables).
23328 </para></entry>
23329 </row>
23331 <row>
23332 <entry role="func_table_entry"><para role="func_signature">
23333 <indexterm>
23334 <primary>pg_is_other_temp_schema</primary>
23335 </indexterm>
23336 <function>pg_is_other_temp_schema</function> ( <type>oid</type> )
23337 <returnvalue>boolean</returnvalue>
23338 </para>
23339 <para>
23340 Returns true if the given OID is the OID of another session's
23341 temporary schema. (This can be useful, for example, to exclude other
23342 sessions' temporary tables from a catalog display.)
23343 </para></entry>
23344 </row>
23346 <row>
23347 <entry role="func_table_entry"><para role="func_signature">
23348 <indexterm>
23349 <primary>pg_jit_available</primary>
23350 </indexterm>
23351 <function>pg_jit_available</function> ()
23352 <returnvalue>boolean</returnvalue>
23353 </para>
23354 <para>
23355 Returns true if a <acronym>JIT</acronym> compiler extension is
23356 available (see <xref linkend="jit"/>) and the
23357 <xref linkend="guc-jit"/> configuration parameter is set to
23358 <literal>on</literal>.
23359 </para></entry>
23360 </row>
23362 <row>
23363 <entry role="func_table_entry"><para role="func_signature">
23364 <indexterm>
23365 <primary>pg_listening_channels</primary>
23366 </indexterm>
23367 <function>pg_listening_channels</function> ()
23368 <returnvalue>setof text</returnvalue>
23369 </para>
23370 <para>
23371 Returns the set of names of asynchronous notification channels that
23372 the current session is listening to.
23373 </para></entry>
23374 </row>
23376 <row>
23377 <entry role="func_table_entry"><para role="func_signature">
23378 <indexterm>
23379 <primary>pg_notification_queue_usage</primary>
23380 </indexterm>
23381 <function>pg_notification_queue_usage</function> ()
23382 <returnvalue>double precision</returnvalue>
23383 </para>
23384 <para>
23385 Returns the fraction (0&ndash;1) of the asynchronous notification
23386 queue's maximum size that is currently occupied by notifications that
23387 are waiting to be processed.
23388 See <xref linkend="sql-listen"/> and <xref linkend="sql-notify"/>
23389 for more information.
23390 </para></entry>
23391 </row>
23393 <row>
23394 <entry role="func_table_entry"><para role="func_signature">
23395 <indexterm>
23396 <primary>pg_postmaster_start_time</primary>
23397 </indexterm>
23398 <function>pg_postmaster_start_time</function> ()
23399 <returnvalue>timestamp with time zone</returnvalue>
23400 </para>
23401 <para>
23402 Returns the time when the server started.
23403 </para></entry>
23404 </row>
23406 <row>
23407 <entry role="func_table_entry"><para role="func_signature">
23408 <indexterm>
23409 <primary>pg_safe_snapshot_blocking_pids</primary>
23410 </indexterm>
23411 <function>pg_safe_snapshot_blocking_pids</function> ( <type>integer</type> )
23412 <returnvalue>integer[]</returnvalue>
23413 </para>
23414 <para>
23415 Returns an array of the process ID(s) of the sessions that are blocking
23416 the server process with the specified process ID from acquiring a safe
23417 snapshot, or an empty array if there is no such server process or it
23418 is not blocked.
23419 </para>
23420 <para>
23421 A session running a <literal>SERIALIZABLE</literal> transaction blocks
23422 a <literal>SERIALIZABLE READ ONLY DEFERRABLE</literal> transaction
23423 from acquiring a snapshot until the latter determines that it is safe
23424 to avoid taking any predicate locks. See
23425 <xref linkend="xact-serializable"/> for more information about
23426 serializable and deferrable transactions.
23427 </para>
23428 <para>
23429 Frequent calls to this function could have some impact on database
23430 performance, because it needs access to the predicate lock manager's
23431 shared state for a short time.
23432 </para></entry>
23433 </row>
23435 <row>
23436 <entry role="func_table_entry"><para role="func_signature">
23437 <indexterm>
23438 <primary>pg_trigger_depth</primary>
23439 </indexterm>
23440 <function>pg_trigger_depth</function> ()
23441 <returnvalue>integer</returnvalue>
23442 </para>
23443 <para>
23444 Returns the current nesting level
23445 of <productname>PostgreSQL</productname> triggers (0 if not called,
23446 directly or indirectly, from inside a trigger).
23447 </para></entry>
23448 </row>
23450 <row>
23451 <entry role="func_table_entry"><para role="func_signature">
23452 <indexterm>
23453 <primary>session_user</primary>
23454 </indexterm>
23455 <function>session_user</function>
23456 <returnvalue>name</returnvalue>
23457 </para>
23458 <para>
23459 Returns the session user's name.
23460 </para></entry>
23461 </row>
23463 <row>
23464 <entry role="func_table_entry"><para role="func_signature">
23465 <indexterm>
23466 <primary>system_user</primary>
23467 </indexterm>
23468 <function>system_user</function>
23469 <returnvalue>text</returnvalue>
23470 </para>
23471 <para>
23472 Returns the authentication method and the identity (if any) that the
23473 user presented during the authentication cycle before they were
23474 assigned a database role. It is represented as
23475 <literal>auth_method:identity</literal> or
23476 <literal>NULL</literal> if the user has not been authenticated (for
23477 example if <link linkend="auth-trust">Trust authentication</link> has
23478 been used).
23479 </para></entry>
23480 </row>
23482 <row>
23483 <entry role="func_table_entry"><para role="func_signature">
23484 <indexterm>
23485 <primary>user</primary>
23486 </indexterm>
23487 <function>user</function>
23488 <returnvalue>name</returnvalue>
23489 </para>
23490 <para>
23491 This is equivalent to <function>current_user</function>.
23492 </para></entry>
23493 </row>
23494 </tbody>
23495 </tgroup>
23496 </table>
23498 <note>
23499 <para>
23500 <function>current_catalog</function>,
23501 <function>current_role</function>,
23502 <function>current_schema</function>,
23503 <function>current_user</function>,
23504 <function>session_user</function>,
23505 and <function>user</function> have special syntactic status
23506 in <acronym>SQL</acronym>: they must be called without trailing
23507 parentheses. In PostgreSQL, parentheses can optionally be used with
23508 <function>current_schema</function>, but not with the others.
23509 </para>
23510 </note>
23512 <para>
23513 The <function>session_user</function> is normally the user who initiated
23514 the current database connection; but superusers can change this setting
23515 with <xref linkend="sql-set-session-authorization"/>.
23516 The <function>current_user</function> is the user identifier
23517 that is applicable for permission checking. Normally it is equal
23518 to the session user, but it can be changed with
23519 <xref linkend="sql-set-role"/>.
23520 It also changes during the execution of
23521 functions with the attribute <literal>SECURITY DEFINER</literal>.
23522 In Unix parlance, the session user is the <quote>real user</quote> and
23523 the current user is the <quote>effective user</quote>.
23524 <function>current_role</function> and <function>user</function> are
23525 synonyms for <function>current_user</function>. (The SQL standard draws
23526 a distinction between <function>current_role</function>
23527 and <function>current_user</function>, but <productname>PostgreSQL</productname>
23528 does not, since it unifies users and roles into a single kind of entity.)
23529 </para>
23531 </sect2>
23533 <sect2 id="functions-info-access">
23534 <title>Access Privilege Inquiry Functions</title>
23536 <indexterm>
23537 <primary>privilege</primary>
23538 <secondary>querying</secondary>
23539 </indexterm>
23541 <para>
23542 <xref linkend="functions-info-access-table"/> lists functions that
23543 allow querying object access privileges programmatically.
23544 (See <xref linkend="ddl-priv"/> for more information about
23545 privileges.)
23546 In these functions, the user whose privileges are being inquired about
23547 can be specified by name or by OID
23548 (<structname>pg_authid</structname>.<structfield>oid</structfield>), or if
23549 the name is given as <literal>public</literal> then the privileges of the
23550 PUBLIC pseudo-role are checked. Also, the <parameter>user</parameter>
23551 argument can be omitted entirely, in which case
23552 the <function>current_user</function> is assumed.
23553 The object that is being inquired about can be specified either by name or
23554 by OID, too. When specifying by name, a schema name can be included if
23555 relevant.
23556 The access privilege of interest is specified by a text string, which must
23557 evaluate to one of the appropriate privilege keywords for the object's type
23558 (e.g., <literal>SELECT</literal>). Optionally, <literal>WITH GRANT
23559 OPTION</literal> can be added to a privilege type to test whether the
23560 privilege is held with grant option. Also, multiple privilege types can be
23561 listed separated by commas, in which case the result will be true if any of
23562 the listed privileges is held. (Case of the privilege string is not
23563 significant, and extra whitespace is allowed between but not within
23564 privilege names.)
23565 Some examples:
23566 <programlisting>
23567 SELECT has_table_privilege('myschema.mytable', 'select');
23568 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
23569 </programlisting>
23570 </para>
23572 <table id="functions-info-access-table">
23573 <title>Access Privilege Inquiry Functions</title>
23574 <tgroup cols="1">
23575 <thead>
23576 <row>
23577 <entry role="func_table_entry"><para role="func_signature">
23578 Function
23579 </para>
23580 <para>
23581 Description
23582 </para></entry>
23583 </row>
23584 </thead>
23586 <tbody>
23587 <row>
23588 <entry role="func_table_entry"><para role="func_signature">
23589 <indexterm>
23590 <primary>has_any_column_privilege</primary>
23591 </indexterm>
23592 <function>has_any_column_privilege</function> (
23593 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23594 <parameter>table</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 any column of table?
23600 This succeeds either if the privilege is held for the whole table, or
23601 if there is a column-level grant of the privilege for at least one
23602 column.
23603 Allowable privilege types are
23604 <literal>SELECT</literal>, <literal>INSERT</literal>,
23605 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
23606 </para></entry>
23607 </row>
23609 <row>
23610 <entry role="func_table_entry"><para role="func_signature">
23611 <indexterm>
23612 <primary>has_column_privilege</primary>
23613 </indexterm>
23614 <function>has_column_privilege</function> (
23615 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23616 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
23617 <parameter>column</parameter> <type>text</type> or <type>smallint</type>,
23618 <parameter>privilege</parameter> <type>text</type> )
23619 <returnvalue>boolean</returnvalue>
23620 </para>
23621 <para>
23622 Does user have privilege for the specified table column?
23623 This succeeds either if the privilege is held for the whole table, or
23624 if there is a column-level grant of the privilege for the column.
23625 The column can be specified by name or by attribute number
23626 (<structname>pg_attribute</structname>.<structfield>attnum</structfield>).
23627 Allowable privilege types are
23628 <literal>SELECT</literal>, <literal>INSERT</literal>,
23629 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
23630 </para></entry>
23631 </row>
23633 <row>
23634 <entry role="func_table_entry"><para role="func_signature">
23635 <indexterm>
23636 <primary>has_database_privilege</primary>
23637 </indexterm>
23638 <function>has_database_privilege</function> (
23639 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23640 <parameter>database</parameter> <type>text</type> or <type>oid</type>,
23641 <parameter>privilege</parameter> <type>text</type> )
23642 <returnvalue>boolean</returnvalue>
23643 </para>
23644 <para>
23645 Does user have privilege for database?
23646 Allowable privilege types are
23647 <literal>CREATE</literal>,
23648 <literal>CONNECT</literal>,
23649 <literal>TEMPORARY</literal>, and
23650 <literal>TEMP</literal> (which is equivalent to
23651 <literal>TEMPORARY</literal>).
23652 </para></entry>
23653 </row>
23655 <row>
23656 <entry role="func_table_entry"><para role="func_signature">
23657 <indexterm>
23658 <primary>has_foreign_data_wrapper_privilege</primary>
23659 </indexterm>
23660 <function>has_foreign_data_wrapper_privilege</function> (
23661 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23662 <parameter>fdw</parameter> <type>text</type> or <type>oid</type>,
23663 <parameter>privilege</parameter> <type>text</type> )
23664 <returnvalue>boolean</returnvalue>
23665 </para>
23666 <para>
23667 Does user have privilege for foreign-data wrapper?
23668 The only allowable privilege type is <literal>USAGE</literal>.
23669 </para></entry>
23670 </row>
23672 <row>
23673 <entry role="func_table_entry"><para role="func_signature">
23674 <indexterm>
23675 <primary>has_function_privilege</primary>
23676 </indexterm>
23677 <function>has_function_privilege</function> (
23678 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23679 <parameter>function</parameter> <type>text</type> or <type>oid</type>,
23680 <parameter>privilege</parameter> <type>text</type> )
23681 <returnvalue>boolean</returnvalue>
23682 </para>
23683 <para>
23684 Does user have privilege for function?
23685 The only allowable privilege type is <literal>EXECUTE</literal>.
23686 </para>
23687 <para>
23688 When specifying a function by name rather than by OID, the allowed
23689 input is the same as for the <type>regprocedure</type> data type (see
23690 <xref linkend="datatype-oid"/>).
23691 An example is:
23692 <programlisting>
23693 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
23694 </programlisting>
23695 </para></entry>
23696 </row>
23698 <row>
23699 <entry role="func_table_entry"><para role="func_signature">
23700 <indexterm>
23701 <primary>has_language_privilege</primary>
23702 </indexterm>
23703 <function>has_language_privilege</function> (
23704 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23705 <parameter>language</parameter> <type>text</type> or <type>oid</type>,
23706 <parameter>privilege</parameter> <type>text</type> )
23707 <returnvalue>boolean</returnvalue>
23708 </para>
23709 <para>
23710 Does user have privilege for language?
23711 The only allowable privilege type is <literal>USAGE</literal>.
23712 </para></entry>
23713 </row>
23715 <row>
23716 <entry role="func_table_entry"><para role="func_signature">
23717 <indexterm>
23718 <primary>has_parameter_privilege</primary>
23719 </indexterm>
23720 <function>has_parameter_privilege</function> (
23721 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23722 <parameter>parameter</parameter> <type>text</type>,
23723 <parameter>privilege</parameter> <type>text</type> )
23724 <returnvalue>boolean</returnvalue>
23725 </para>
23726 <para>
23727 Does user have privilege for configuration parameter?
23728 The parameter name is case-insensitive.
23729 Allowable privilege types are <literal>SET</literal>
23730 and <literal>ALTER SYSTEM</literal>.
23731 </para></entry>
23732 </row>
23734 <row>
23735 <entry role="func_table_entry"><para role="func_signature">
23736 <indexterm>
23737 <primary>has_schema_privilege</primary>
23738 </indexterm>
23739 <function>has_schema_privilege</function> (
23740 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23741 <parameter>schema</parameter> <type>text</type> or <type>oid</type>,
23742 <parameter>privilege</parameter> <type>text</type> )
23743 <returnvalue>boolean</returnvalue>
23744 </para>
23745 <para>
23746 Does user have privilege for schema?
23747 Allowable privilege types are
23748 <literal>CREATE</literal> and
23749 <literal>USAGE</literal>.
23750 </para></entry>
23751 </row>
23753 <row>
23754 <entry role="func_table_entry"><para role="func_signature">
23755 <indexterm>
23756 <primary>has_sequence_privilege</primary>
23757 </indexterm>
23758 <function>has_sequence_privilege</function> (
23759 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23760 <parameter>sequence</parameter> <type>text</type> or <type>oid</type>,
23761 <parameter>privilege</parameter> <type>text</type> )
23762 <returnvalue>boolean</returnvalue>
23763 </para>
23764 <para>
23765 Does user have privilege for sequence?
23766 Allowable privilege types are
23767 <literal>USAGE</literal>,
23768 <literal>SELECT</literal>, and
23769 <literal>UPDATE</literal>.
23770 </para></entry>
23771 </row>
23773 <row>
23774 <entry role="func_table_entry"><para role="func_signature">
23775 <indexterm>
23776 <primary>has_server_privilege</primary>
23777 </indexterm>
23778 <function>has_server_privilege</function> (
23779 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23780 <parameter>server</parameter> <type>text</type> or <type>oid</type>,
23781 <parameter>privilege</parameter> <type>text</type> )
23782 <returnvalue>boolean</returnvalue>
23783 </para>
23784 <para>
23785 Does user have privilege for foreign server?
23786 The only allowable privilege type is <literal>USAGE</literal>.
23787 </para></entry>
23788 </row>
23790 <row>
23791 <entry role="func_table_entry"><para role="func_signature">
23792 <indexterm>
23793 <primary>has_table_privilege</primary>
23794 </indexterm>
23795 <function>has_table_privilege</function> (
23796 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23797 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
23798 <parameter>privilege</parameter> <type>text</type> )
23799 <returnvalue>boolean</returnvalue>
23800 </para>
23801 <para>
23802 Does user have privilege for table?
23803 Allowable privilege types
23804 are <literal>SELECT</literal>, <literal>INSERT</literal>,
23805 <literal>UPDATE</literal>, <literal>DELETE</literal>,
23806 <literal>TRUNCATE</literal>, <literal>REFERENCES</literal>,
23807 and <literal>TRIGGER</literal>.
23808 </para></entry>
23809 </row>
23811 <row>
23812 <entry role="func_table_entry"><para role="func_signature">
23813 <indexterm>
23814 <primary>has_tablespace_privilege</primary>
23815 </indexterm>
23816 <function>has_tablespace_privilege</function> (
23817 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23818 <parameter>tablespace</parameter> <type>text</type> or <type>oid</type>,
23819 <parameter>privilege</parameter> <type>text</type> )
23820 <returnvalue>boolean</returnvalue>
23821 </para>
23822 <para>
23823 Does user have privilege for tablespace?
23824 The only allowable privilege type is <literal>CREATE</literal>.
23825 </para></entry>
23826 </row>
23828 <row>
23829 <entry role="func_table_entry"><para role="func_signature">
23830 <indexterm>
23831 <primary>has_type_privilege</primary>
23832 </indexterm>
23833 <function>has_type_privilege</function> (
23834 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23835 <parameter>type</parameter> <type>text</type> or <type>oid</type>,
23836 <parameter>privilege</parameter> <type>text</type> )
23837 <returnvalue>boolean</returnvalue>
23838 </para>
23839 <para>
23840 Does user have privilege for data type?
23841 The only allowable privilege type is <literal>USAGE</literal>.
23842 When specifying a type by name rather than by OID, the allowed input
23843 is the same as for the <type>regtype</type> data type (see
23844 <xref linkend="datatype-oid"/>).
23845 </para></entry>
23846 </row>
23848 <row>
23849 <entry role="func_table_entry"><para role="func_signature">
23850 <indexterm>
23851 <primary>pg_has_role</primary>
23852 </indexterm>
23853 <function>pg_has_role</function> (
23854 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23855 <parameter>role</parameter> <type>text</type> or <type>oid</type>,
23856 <parameter>privilege</parameter> <type>text</type> )
23857 <returnvalue>boolean</returnvalue>
23858 </para>
23859 <para>
23860 Does user have privilege for role?
23861 Allowable privilege types are
23862 <literal>MEMBER</literal>, <literal>USAGE</literal>,
23863 and <literal>SET</literal>.
23864 <literal>MEMBER</literal> denotes direct or indirect membership in
23865 the role without regard to what specific privileges may be conferred.
23866 <literal>USAGE</literal> denotes whether the privileges of the role
23867 are immediately available without doing <command>SET ROLE</command>,
23868 while <literal>SET</literal> denotes whether it is possible to change
23869 to the role using the <literal>SET ROLE</literal> command.
23870 This function does not allow the special case of
23871 setting <parameter>user</parameter> to <literal>public</literal>,
23872 because the PUBLIC pseudo-role can never be a member of real roles.
23873 </para></entry>
23874 </row>
23876 <row>
23877 <entry role="func_table_entry"><para role="func_signature">
23878 <indexterm>
23879 <primary>row_security_active</primary>
23880 </indexterm>
23881 <function>row_security_active</function> (
23882 <parameter>table</parameter> <type>text</type> or <type>oid</type> )
23883 <returnvalue>boolean</returnvalue>
23884 </para>
23885 <para>
23886 Is row-level security active for the specified table in the context of
23887 the current user and current environment?
23888 </para></entry>
23889 </row>
23890 </tbody>
23891 </tgroup>
23892 </table>
23894 <para>
23895 <xref linkend="functions-aclitem-op-table"/> shows the operators
23896 available for the <type>aclitem</type> type, which is the catalog
23897 representation of access privileges. See <xref linkend="ddl-priv"/>
23898 for information about how to read access privilege values.
23899 </para>
23901 <table id="functions-aclitem-op-table">
23902 <title><type>aclitem</type> Operators</title>
23903 <tgroup cols="1">
23904 <thead>
23905 <row>
23906 <entry role="func_table_entry"><para role="func_signature">
23907 Operator
23908 </para>
23909 <para>
23910 Description
23911 </para>
23912 <para>
23913 Example(s)
23914 </para></entry>
23915 </row>
23916 </thead>
23918 <tbody>
23919 <row>
23920 <entry role="func_table_entry"><para role="func_signature">
23921 <indexterm>
23922 <primary>aclitemeq</primary>
23923 </indexterm>
23924 <type>aclitem</type> <literal>=</literal> <type>aclitem</type>
23925 <returnvalue>boolean</returnvalue>
23926 </para>
23927 <para>
23928 Are <type>aclitem</type>s equal? (Notice that
23929 type <type>aclitem</type> lacks the usual set of comparison
23930 operators; it has only equality. In turn, <type>aclitem</type>
23931 arrays can only be compared for equality.)
23932 </para>
23933 <para>
23934 <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem</literal>
23935 <returnvalue>f</returnvalue>
23936 </para></entry>
23937 </row>
23939 <row>
23940 <entry role="func_table_entry"><para role="func_signature">
23941 <indexterm>
23942 <primary>aclcontains</primary>
23943 </indexterm>
23944 <type>aclitem[]</type> <literal>@&gt;</literal> <type>aclitem</type>
23945 <returnvalue>boolean</returnvalue>
23946 </para>
23947 <para>
23948 Does array contain the specified privileges? (This is true if there
23949 is an array entry that matches the <type>aclitem</type>'s grantee and
23950 grantor, and has at least the specified set of privileges.)
23951 </para>
23952 <para>
23953 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @&gt; 'calvin=r*/hobbes'::aclitem</literal>
23954 <returnvalue>t</returnvalue>
23955 </para></entry>
23956 </row>
23958 <row>
23959 <entry role="func_table_entry"><para role="func_signature">
23960 <type>aclitem[]</type> <literal>~</literal> <type>aclitem</type>
23961 <returnvalue>boolean</returnvalue>
23962 </para>
23963 <para>
23964 This is a deprecated alias for <literal>@&gt;</literal>.
23965 </para>
23966 <para>
23967 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem</literal>
23968 <returnvalue>t</returnvalue>
23969 </para></entry>
23970 </row>
23971 </tbody>
23972 </tgroup>
23973 </table>
23975 <para>
23976 <xref linkend="functions-aclitem-fn-table"/> shows some additional
23977 functions to manage the <type>aclitem</type> type.
23978 </para>
23980 <table id="functions-aclitem-fn-table">
23981 <title><type>aclitem</type> Functions</title>
23982 <tgroup cols="1">
23983 <thead>
23984 <row>
23985 <entry role="func_table_entry"><para role="func_signature">
23986 Function
23987 </para>
23988 <para>
23989 Description
23990 </para></entry>
23991 </row>
23992 </thead>
23994 <tbody>
23995 <row>
23996 <entry role="func_table_entry"><para role="func_signature">
23997 <indexterm>
23998 <primary>acldefault</primary>
23999 </indexterm>
24000 <function>acldefault</function> (
24001 <parameter>type</parameter> <type>"char"</type>,
24002 <parameter>ownerId</parameter> <type>oid</type> )
24003 <returnvalue>aclitem[]</returnvalue>
24004 </para>
24005 <para>
24006 Constructs an <type>aclitem</type> array holding the default access
24007 privileges for an object of type <parameter>type</parameter> belonging
24008 to the role with OID <parameter>ownerId</parameter>. This represents
24009 the access privileges that will be assumed when an object's ACL entry
24010 is null. (The default access privileges are described in
24011 <xref linkend="ddl-priv"/>.)
24012 The <parameter>type</parameter> parameter must be one of
24013 'c' for <literal>COLUMN</literal>,
24014 'r' for <literal>TABLE</literal> and table-like objects,
24015 's' for <literal>SEQUENCE</literal>,
24016 'd' for <literal>DATABASE</literal>,
24017 'f' for <literal>FUNCTION</literal> or <literal>PROCEDURE</literal>,
24018 'l' for <literal>LANGUAGE</literal>,
24019 'L' for <literal>LARGE OBJECT</literal>,
24020 'n' for <literal>SCHEMA</literal>,
24021 'p' for <literal>PARAMETER</literal>,
24022 't' for <literal>TABLESPACE</literal>,
24023 'F' for <literal>FOREIGN DATA WRAPPER</literal>,
24024 'S' for <literal>FOREIGN SERVER</literal>,
24026 'T' for <literal>TYPE</literal> or <literal>DOMAIN</literal>.
24027 </para></entry>
24028 </row>
24030 <row>
24031 <entry role="func_table_entry"><para role="func_signature">
24032 <indexterm>
24033 <primary>aclexplode</primary>
24034 </indexterm>
24035 <function>aclexplode</function> ( <type>aclitem[]</type> )
24036 <returnvalue>setof record</returnvalue>
24037 ( <parameter>grantor</parameter> <type>oid</type>,
24038 <parameter>grantee</parameter> <type>oid</type>,
24039 <parameter>privilege_type</parameter> <type>text</type>,
24040 <parameter>is_grantable</parameter> <type>boolean</type> )
24041 </para>
24042 <para>
24043 Returns the <type>aclitem</type> array as a set of rows.
24044 If the grantee is the pseudo-role PUBLIC, it is represented by zero in
24045 the <parameter>grantee</parameter> column. Each granted privilege is
24046 represented as <literal>SELECT</literal>, <literal>INSERT</literal>,
24047 etc (see <xref linkend="privilege-abbrevs-table"/> for a full list).
24048 Note that each privilege is broken out as a separate row, so
24049 only one keyword appears in the <parameter>privilege_type</parameter>
24050 column.
24051 </para></entry>
24052 </row>
24054 <row>
24055 <entry role="func_table_entry"><para role="func_signature">
24056 <indexterm>
24057 <primary>makeaclitem</primary>
24058 </indexterm>
24059 <function>makeaclitem</function> (
24060 <parameter>grantee</parameter> <type>oid</type>,
24061 <parameter>grantor</parameter> <type>oid</type>,
24062 <parameter>privileges</parameter> <type>text</type>,
24063 <parameter>is_grantable</parameter> <type>boolean</type> )
24064 <returnvalue>aclitem</returnvalue>
24065 </para>
24066 <para>
24067 Constructs an <type>aclitem</type> with the given properties.
24068 <parameter>privileges</parameter> is a comma-separated list of
24069 privilege names such as <literal>SELECT</literal>,
24070 <literal>INSERT</literal>, etc, all of which are set in the
24071 result. (Case of the privilege string is not significant, and
24072 extra whitespace is allowed between but not within privilege
24073 names.)
24074 </para></entry>
24075 </row>
24076 </tbody>
24077 </tgroup>
24078 </table>
24080 </sect2>
24082 <sect2 id="functions-info-schema">
24083 <title>Schema Visibility Inquiry Functions</title>
24085 <para>
24086 <xref linkend="functions-info-schema-table"/> shows functions that
24087 determine whether a certain object is <firstterm>visible</firstterm> in the
24088 current schema search path.
24089 For example, a table is said to be visible if its
24090 containing schema is in the search path and no table of the same
24091 name appears earlier in the search path. This is equivalent to the
24092 statement that the table can be referenced by name without explicit
24093 schema qualification. Thus, to list the names of all visible tables:
24094 <programlisting>
24095 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
24096 </programlisting>
24097 For functions and operators, an object in the search path is said to be
24098 visible if there is no object of the same name <emphasis>and argument data
24099 type(s)</emphasis> earlier in the path. For operator classes and families,
24100 both the name and the associated index access method are considered.
24101 </para>
24103 <indexterm>
24104 <primary>search path</primary>
24105 <secondary>object visibility</secondary>
24106 </indexterm>
24108 <table id="functions-info-schema-table">
24109 <title>Schema Visibility Inquiry Functions</title>
24110 <tgroup cols="1">
24111 <thead>
24112 <row>
24113 <entry role="func_table_entry"><para role="func_signature">
24114 Function
24115 </para>
24116 <para>
24117 Description
24118 </para></entry>
24119 </row>
24120 </thead>
24122 <tbody>
24123 <row>
24124 <entry role="func_table_entry"><para role="func_signature">
24125 <indexterm>
24126 <primary>pg_collation_is_visible</primary>
24127 </indexterm>
24128 <function>pg_collation_is_visible</function> ( <parameter>collation</parameter> <type>oid</type> )
24129 <returnvalue>boolean</returnvalue>
24130 </para>
24131 <para>
24132 Is collation visible in search path?
24133 </para></entry>
24134 </row>
24136 <row>
24137 <entry role="func_table_entry"><para role="func_signature">
24138 <indexterm>
24139 <primary>pg_conversion_is_visible</primary>
24140 </indexterm>
24141 <function>pg_conversion_is_visible</function> ( <parameter>conversion</parameter> <type>oid</type> )
24142 <returnvalue>boolean</returnvalue>
24143 </para>
24144 <para>
24145 Is conversion visible in search path?
24146 </para></entry>
24147 </row>
24149 <row>
24150 <entry role="func_table_entry"><para role="func_signature">
24151 <indexterm>
24152 <primary>pg_function_is_visible</primary>
24153 </indexterm>
24154 <function>pg_function_is_visible</function> ( <parameter>function</parameter> <type>oid</type> )
24155 <returnvalue>boolean</returnvalue>
24156 </para>
24157 <para>
24158 Is function visible in search path?
24159 (This also works for procedures and aggregates.)
24160 </para></entry>
24161 </row>
24163 <row>
24164 <entry role="func_table_entry"><para role="func_signature">
24165 <indexterm>
24166 <primary>pg_opclass_is_visible</primary>
24167 </indexterm>
24168 <function>pg_opclass_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
24169 <returnvalue>boolean</returnvalue>
24170 </para>
24171 <para>
24172 Is operator class visible in search path?
24173 </para></entry>
24174 </row>
24176 <row>
24177 <entry role="func_table_entry"><para role="func_signature">
24178 <indexterm>
24179 <primary>pg_operator_is_visible</primary>
24180 </indexterm>
24181 <function>pg_operator_is_visible</function> ( <parameter>operator</parameter> <type>oid</type> )
24182 <returnvalue>boolean</returnvalue>
24183 </para>
24184 <para>
24185 Is operator visible in search path?
24186 </para></entry>
24187 </row>
24189 <row>
24190 <entry role="func_table_entry"><para role="func_signature">
24191 <indexterm>
24192 <primary>pg_opfamily_is_visible</primary>
24193 </indexterm>
24194 <function>pg_opfamily_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
24195 <returnvalue>boolean</returnvalue>
24196 </para>
24197 <para>
24198 Is operator family visible in search path?
24199 </para></entry>
24200 </row>
24202 <row>
24203 <entry role="func_table_entry"><para role="func_signature">
24204 <indexterm>
24205 <primary>pg_statistics_obj_is_visible</primary>
24206 </indexterm>
24207 <function>pg_statistics_obj_is_visible</function> ( <parameter>stat</parameter> <type>oid</type> )
24208 <returnvalue>boolean</returnvalue>
24209 </para>
24210 <para>
24211 Is statistics object visible in search path?
24212 </para></entry>
24213 </row>
24215 <row>
24216 <entry role="func_table_entry"><para role="func_signature">
24217 <indexterm>
24218 <primary>pg_table_is_visible</primary>
24219 </indexterm>
24220 <function>pg_table_is_visible</function> ( <parameter>table</parameter> <type>oid</type> )
24221 <returnvalue>boolean</returnvalue>
24222 </para>
24223 <para>
24224 Is table visible in search path?
24225 (This works for all types of relations, including views, materialized
24226 views, indexes, sequences and foreign tables.)
24227 </para></entry>
24228 </row>
24230 <row>
24231 <entry role="func_table_entry"><para role="func_signature">
24232 <indexterm>
24233 <primary>pg_ts_config_is_visible</primary>
24234 </indexterm>
24235 <function>pg_ts_config_is_visible</function> ( <parameter>config</parameter> <type>oid</type> )
24236 <returnvalue>boolean</returnvalue>
24237 </para>
24238 <para>
24239 Is text search configuration visible in search path?
24240 </para></entry>
24241 </row>
24243 <row>
24244 <entry role="func_table_entry"><para role="func_signature">
24245 <indexterm>
24246 <primary>pg_ts_dict_is_visible</primary>
24247 </indexterm>
24248 <function>pg_ts_dict_is_visible</function> ( <parameter>dict</parameter> <type>oid</type> )
24249 <returnvalue>boolean</returnvalue>
24250 </para>
24251 <para>
24252 Is text search dictionary visible in search path?
24253 </para></entry>
24254 </row>
24256 <row>
24257 <entry role="func_table_entry"><para role="func_signature">
24258 <indexterm>
24259 <primary>pg_ts_parser_is_visible</primary>
24260 </indexterm>
24261 <function>pg_ts_parser_is_visible</function> ( <parameter>parser</parameter> <type>oid</type> )
24262 <returnvalue>boolean</returnvalue>
24263 </para>
24264 <para>
24265 Is text search parser visible in search path?
24266 </para></entry>
24267 </row>
24269 <row>
24270 <entry role="func_table_entry"><para role="func_signature">
24271 <indexterm>
24272 <primary>pg_ts_template_is_visible</primary>
24273 </indexterm>
24274 <function>pg_ts_template_is_visible</function> ( <parameter>template</parameter> <type>oid</type> )
24275 <returnvalue>boolean</returnvalue>
24276 </para>
24277 <para>
24278 Is text search template visible in search path?
24279 </para></entry>
24280 </row>
24282 <row>
24283 <entry role="func_table_entry"><para role="func_signature">
24284 <indexterm>
24285 <primary>pg_type_is_visible</primary>
24286 </indexterm>
24287 <function>pg_type_is_visible</function> ( <parameter>type</parameter> <type>oid</type> )
24288 <returnvalue>boolean</returnvalue>
24289 </para>
24290 <para>
24291 Is type (or domain) visible in search path?
24292 </para></entry>
24293 </row>
24294 </tbody>
24295 </tgroup>
24296 </table>
24298 <para>
24299 All these functions require object OIDs to identify the object to be
24300 checked. If you want to test an object by name, it is convenient to use
24301 the OID alias types (<type>regclass</type>, <type>regtype</type>,
24302 <type>regprocedure</type>, <type>regoperator</type>, <type>regconfig</type>,
24303 or <type>regdictionary</type>),
24304 for example:
24305 <programlisting>
24306 SELECT pg_type_is_visible('myschema.widget'::regtype);
24307 </programlisting>
24308 Note that it would not make much sense to test a non-schema-qualified
24309 type name in this way &mdash; if the name can be recognized at all, it must be visible.
24310 </para>
24312 </sect2>
24314 <sect2 id="functions-info-catalog">
24315 <title>System Catalog Information Functions</title>
24317 <para>
24318 <xref linkend="functions-info-catalog-table"/> lists functions that
24319 extract information from the system catalogs.
24320 </para>
24322 <table id="functions-info-catalog-table">
24323 <title>System Catalog Information Functions</title>
24324 <tgroup cols="1">
24325 <thead>
24326 <row>
24327 <entry role="func_table_entry"><para role="func_signature">
24328 Function
24329 </para>
24330 <para>
24331 Description
24332 </para></entry>
24333 </row>
24334 </thead>
24336 <tbody>
24337 <row>
24338 <entry role="func_table_entry"><para role="func_signature">
24339 <indexterm>
24340 <primary>format_type</primary>
24341 </indexterm>
24342 <function>format_type</function> ( <parameter>type</parameter> <type>oid</type>, <parameter>typemod</parameter> <type>integer</type> )
24343 <returnvalue>text</returnvalue>
24344 </para>
24345 <para>
24346 Returns the SQL name for a data type that is identified by its type
24347 OID and possibly a type modifier. Pass NULL for the type modifier if
24348 no specific modifier is known.
24349 </para></entry>
24350 </row>
24352 <row>
24353 <entry id="pg-char-to-encoding" role="func_table_entry"><para role="func_signature">
24354 <indexterm>
24355 <primary>pg_char_to_encoding</primary>
24356 </indexterm>
24357 <function>pg_char_to_encoding</function> ( <parameter>encoding</parameter> <type>name</type> )
24358 <returnvalue>integer</returnvalue>
24359 </para>
24360 <para>
24361 Converts the supplied encoding name into an integer representing the
24362 internal identifier used in some system catalog tables.
24363 Returns <literal>-1</literal> if an unknown encoding name is provided.
24364 </para></entry>
24365 </row>
24367 <row>
24368 <entry id="pg-encoding-to-char" role="func_table_entry"><para role="func_signature">
24369 <indexterm>
24370 <primary>pg_encoding_to_char</primary>
24371 </indexterm>
24372 <function>pg_encoding_to_char</function> ( <parameter>encoding</parameter> <type>integer</type> )
24373 <returnvalue>name</returnvalue>
24374 </para>
24375 <para>
24376 Converts the integer used as the internal identifier of an encoding in some
24377 system catalog tables into a human-readable string.
24378 Returns an empty string if an invalid encoding number is provided.
24379 </para></entry>
24380 </row>
24382 <row>
24383 <entry role="func_table_entry"><para role="func_signature">
24384 <indexterm>
24385 <primary>pg_get_catalog_foreign_keys</primary>
24386 </indexterm>
24387 <function>pg_get_catalog_foreign_keys</function> ()
24388 <returnvalue>setof record</returnvalue>
24389 ( <parameter>fktable</parameter> <type>regclass</type>,
24390 <parameter>fkcols</parameter> <type>text[]</type>,
24391 <parameter>pktable</parameter> <type>regclass</type>,
24392 <parameter>pkcols</parameter> <type>text[]</type>,
24393 <parameter>is_array</parameter> <type>boolean</type>,
24394 <parameter>is_opt</parameter> <type>boolean</type> )
24395 </para>
24396 <para>
24397 Returns a set of records describing the foreign key relationships
24398 that exist within the <productname>PostgreSQL</productname> system
24399 catalogs.
24400 The <parameter>fktable</parameter> column contains the name of the
24401 referencing catalog, and the <parameter>fkcols</parameter> column
24402 contains the name(s) of the referencing column(s). Similarly,
24403 the <parameter>pktable</parameter> column contains the name of the
24404 referenced catalog, and the <parameter>pkcols</parameter> column
24405 contains the name(s) of the referenced column(s).
24406 If <parameter>is_array</parameter> is true, the last referencing
24407 column is an array, each of whose elements should match some entry
24408 in the referenced catalog.
24409 If <parameter>is_opt</parameter> is true, the referencing column(s)
24410 are allowed to contain zeroes instead of a valid reference.
24411 </para></entry>
24412 </row>
24414 <row>
24415 <entry role="func_table_entry"><para role="func_signature">
24416 <indexterm>
24417 <primary>pg_get_constraintdef</primary>
24418 </indexterm>
24419 <function>pg_get_constraintdef</function> ( <parameter>constraint</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24420 <returnvalue>text</returnvalue>
24421 </para>
24422 <para>
24423 Reconstructs the creating command for a constraint.
24424 (This is a decompiled reconstruction, not the original text
24425 of the command.)
24426 </para></entry>
24427 </row>
24429 <row>
24430 <entry role="func_table_entry"><para role="func_signature">
24431 <indexterm>
24432 <primary>pg_get_expr</primary>
24433 </indexterm>
24434 <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> )
24435 <returnvalue>text</returnvalue>
24436 </para>
24437 <para>
24438 Decompiles the internal form of an expression stored in the system
24439 catalogs, such as the default value for a column. If the expression
24440 might contain Vars, specify the OID of the relation they refer to as
24441 the second parameter; if no Vars are expected, passing zero is
24442 sufficient.
24443 </para></entry>
24444 </row>
24446 <row>
24447 <entry role="func_table_entry"><para role="func_signature">
24448 <indexterm>
24449 <primary>pg_get_functiondef</primary>
24450 </indexterm>
24451 <function>pg_get_functiondef</function> ( <parameter>func</parameter> <type>oid</type> )
24452 <returnvalue>text</returnvalue>
24453 </para>
24454 <para>
24455 Reconstructs the creating command for a function or procedure.
24456 (This is a decompiled reconstruction, not the original text
24457 of the command.)
24458 The result is a complete <command>CREATE OR REPLACE FUNCTION</command>
24459 or <command>CREATE OR REPLACE PROCEDURE</command> statement.
24460 </para></entry>
24461 </row>
24463 <row>
24464 <entry role="func_table_entry"><para role="func_signature">
24465 <indexterm>
24466 <primary>pg_get_function_arguments</primary>
24467 </indexterm>
24468 <function>pg_get_function_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
24469 <returnvalue>text</returnvalue>
24470 </para>
24471 <para>
24472 Reconstructs the argument list of a function or procedure, in the form
24473 it would need to appear in within <command>CREATE FUNCTION</command>
24474 (including default values).
24475 </para></entry>
24476 </row>
24478 <row>
24479 <entry role="func_table_entry"><para role="func_signature">
24480 <indexterm>
24481 <primary>pg_get_function_identity_arguments</primary>
24482 </indexterm>
24483 <function>pg_get_function_identity_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
24484 <returnvalue>text</returnvalue>
24485 </para>
24486 <para>
24487 Reconstructs the argument list necessary to identify a function or
24488 procedure, in the form it would need to appear in within commands such
24489 as <command>ALTER FUNCTION</command>. This form omits default values.
24490 </para></entry>
24491 </row>
24493 <row>
24494 <entry role="func_table_entry"><para role="func_signature">
24495 <indexterm>
24496 <primary>pg_get_function_result</primary>
24497 </indexterm>
24498 <function>pg_get_function_result</function> ( <parameter>func</parameter> <type>oid</type> )
24499 <returnvalue>text</returnvalue>
24500 </para>
24501 <para>
24502 Reconstructs the <literal>RETURNS</literal> clause of a function, in
24503 the form it would need to appear in within <command>CREATE
24504 FUNCTION</command>. Returns <literal>NULL</literal> for a procedure.
24505 </para></entry>
24506 </row>
24508 <row>
24509 <entry role="func_table_entry"><para role="func_signature">
24510 <indexterm>
24511 <primary>pg_get_indexdef</primary>
24512 </indexterm>
24513 <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> )
24514 <returnvalue>text</returnvalue>
24515 </para>
24516 <para>
24517 Reconstructs the creating command for an index.
24518 (This is a decompiled reconstruction, not the original text
24519 of the command.) If <parameter>column</parameter> is supplied and is
24520 not zero, only the definition of that column is reconstructed.
24521 </para></entry>
24522 </row>
24524 <row>
24525 <entry role="func_table_entry"><para role="func_signature">
24526 <indexterm>
24527 <primary>pg_get_keywords</primary>
24528 </indexterm>
24529 <function>pg_get_keywords</function> ()
24530 <returnvalue>setof record</returnvalue>
24531 ( <parameter>word</parameter> <type>text</type>,
24532 <parameter>catcode</parameter> <type>"char"</type>,
24533 <parameter>barelabel</parameter> <type>boolean</type>,
24534 <parameter>catdesc</parameter> <type>text</type>,
24535 <parameter>baredesc</parameter> <type>text</type> )
24536 </para>
24537 <para>
24538 Returns a set of records describing the SQL keywords recognized by the
24539 server. The <parameter>word</parameter> column contains the
24540 keyword. The <parameter>catcode</parameter> column contains a
24541 category code: <literal>U</literal> for an unreserved
24542 keyword, <literal>C</literal> for a keyword that can be a column
24543 name, <literal>T</literal> for a keyword that can be a type or
24544 function name, or <literal>R</literal> for a fully reserved keyword.
24545 The <parameter>barelabel</parameter> column
24546 contains <literal>true</literal> if the keyword can be used as
24547 a <quote>bare</quote> column label in <command>SELECT</command> lists,
24548 or <literal>false</literal> if it can only be used
24549 after <literal>AS</literal>.
24550 The <parameter>catdesc</parameter> column contains a
24551 possibly-localized string describing the keyword's category.
24552 The <parameter>baredesc</parameter> column contains a
24553 possibly-localized string describing the keyword's column label status.
24554 </para></entry>
24555 </row>
24557 <row>
24558 <entry role="func_table_entry"><para role="func_signature">
24559 <indexterm>
24560 <primary>pg_get_partkeydef</primary>
24561 </indexterm>
24562 <function>pg_get_partkeydef</function> ( <parameter>table</parameter> <type>oid</type> )
24563 <returnvalue>text</returnvalue>
24564 </para>
24565 <para>
24566 Reconstructs the definition of a partitioned table's partition
24567 key, in the form it would have in the <literal>PARTITION
24568 BY</literal> clause of <command>CREATE TABLE</command>.
24569 (This is a decompiled reconstruction, not the original text
24570 of the command.)
24571 </para></entry>
24572 </row>
24574 <row>
24575 <entry role="func_table_entry"><para role="func_signature">
24576 <indexterm>
24577 <primary>pg_get_ruledef</primary>
24578 </indexterm>
24579 <function>pg_get_ruledef</function> ( <parameter>rule</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24580 <returnvalue>text</returnvalue>
24581 </para>
24582 <para>
24583 Reconstructs the creating command for a rule.
24584 (This is a decompiled reconstruction, not the original text
24585 of the command.)
24586 </para></entry>
24587 </row>
24589 <row>
24590 <entry role="func_table_entry"><para role="func_signature">
24591 <indexterm>
24592 <primary>pg_get_serial_sequence</primary>
24593 </indexterm>
24594 <function>pg_get_serial_sequence</function> ( <parameter>table</parameter> <type>text</type>, <parameter>column</parameter> <type>text</type> )
24595 <returnvalue>text</returnvalue>
24596 </para>
24597 <para>
24598 Returns the name of the sequence associated with a column,
24599 or NULL if no sequence is associated with the column.
24600 If the column is an identity column, the associated sequence is the
24601 sequence internally created for that column.
24602 For columns created using one of the serial types
24603 (<type>serial</type>, <type>smallserial</type>, <type>bigserial</type>),
24604 it is the sequence created for that serial column definition.
24605 In the latter case, the association can be modified or removed
24606 with <command>ALTER SEQUENCE OWNED BY</command>.
24607 (This function probably should have been
24608 called <function>pg_get_owned_sequence</function>; its current name
24609 reflects the fact that it has historically been used with serial-type
24610 columns.) The first parameter is a table name with optional
24611 schema, and the second parameter is a column name. Because the first
24612 parameter potentially contains both schema and table names, it is
24613 parsed per usual SQL rules, meaning it is lower-cased by default.
24614 The second parameter, being just a column name, is treated literally
24615 and so has its case preserved. The result is suitably formatted
24616 for passing to the sequence functions (see
24617 <xref linkend="functions-sequence"/>).
24618 </para>
24619 <para>
24620 A typical use is in reading the current value of the sequence for an
24621 identity or serial column, for example:
24622 <programlisting>
24623 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
24624 </programlisting>
24625 </para></entry>
24626 </row>
24628 <row>
24629 <entry role="func_table_entry"><para role="func_signature">
24630 <indexterm>
24631 <primary>pg_get_statisticsobjdef</primary>
24632 </indexterm>
24633 <function>pg_get_statisticsobjdef</function> ( <parameter>statobj</parameter> <type>oid</type> )
24634 <returnvalue>text</returnvalue>
24635 </para>
24636 <para>
24637 Reconstructs the creating command for an extended statistics object.
24638 (This is a decompiled reconstruction, not the original text
24639 of the command.)
24640 </para></entry>
24641 </row>
24643 <row>
24644 <entry role="func_table_entry"><para role="func_signature">
24645 <indexterm>
24646 <primary>pg_get_triggerdef</primary>
24647 </indexterm>
24648 <function>pg_get_triggerdef</function> ( <parameter>trigger</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24649 <returnvalue>text</returnvalue>
24650 </para>
24651 <para>
24652 Reconstructs the creating command for a trigger.
24653 (This is a decompiled reconstruction, not the original text
24654 of the command.)
24655 </para></entry>
24656 </row>
24658 <row>
24659 <entry role="func_table_entry"><para role="func_signature">
24660 <indexterm>
24661 <primary>pg_get_userbyid</primary>
24662 </indexterm>
24663 <function>pg_get_userbyid</function> ( <parameter>role</parameter> <type>oid</type> )
24664 <returnvalue>name</returnvalue>
24665 </para>
24666 <para>
24667 Returns a role's name given its OID.
24668 </para></entry>
24669 </row>
24671 <row>
24672 <entry role="func_table_entry"><para role="func_signature">
24673 <indexterm>
24674 <primary>pg_get_viewdef</primary>
24675 </indexterm>
24676 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24677 <returnvalue>text</returnvalue>
24678 </para>
24679 <para>
24680 Reconstructs the underlying <command>SELECT</command> command for a
24681 view or materialized view. (This is a decompiled reconstruction, not
24682 the original text of the command.)
24683 </para></entry>
24684 </row>
24686 <row>
24687 <entry role="func_table_entry"><para role="func_signature">
24688 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type>, <parameter>wrap_column</parameter> <type>integer</type> )
24689 <returnvalue>text</returnvalue>
24690 </para>
24691 <para>
24692 Reconstructs the underlying <command>SELECT</command> command for a
24693 view or materialized view. (This is a decompiled reconstruction, not
24694 the original text of the command.) In this form of the function,
24695 pretty-printing is always enabled, and long lines are wrapped to try
24696 to keep them shorter than the specified number of columns.
24697 </para></entry>
24698 </row>
24700 <row>
24701 <entry role="func_table_entry"><para role="func_signature">
24702 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>text</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24703 <returnvalue>text</returnvalue>
24704 </para>
24705 <para>
24706 Reconstructs the underlying <command>SELECT</command> command for a
24707 view or materialized view, working from a textual name for the view
24708 rather than its OID. (This is deprecated; use the OID variant
24709 instead.)
24710 </para></entry>
24711 </row>
24713 <row>
24714 <entry role="func_table_entry"><para role="func_signature">
24715 <indexterm>
24716 <primary>pg_index_column_has_property</primary>
24717 </indexterm>
24718 <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> )
24719 <returnvalue>boolean</returnvalue>
24720 </para>
24721 <para>
24722 Tests whether an index column has the named property.
24723 Common index column properties are listed in
24724 <xref linkend="functions-info-index-column-props"/>.
24725 (Note that extension access methods can define additional property
24726 names for their indexes.)
24727 <literal>NULL</literal> is returned if the property name is not known
24728 or does not apply to the particular object, or if the OID or column
24729 number does not identify a valid object.
24730 </para></entry>
24731 </row>
24733 <row>
24734 <entry role="func_table_entry"><para role="func_signature">
24735 <indexterm>
24736 <primary>pg_index_has_property</primary>
24737 </indexterm>
24738 <function>pg_index_has_property</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>property</parameter> <type>text</type> )
24739 <returnvalue>boolean</returnvalue>
24740 </para>
24741 <para>
24742 Tests whether an index has the named property.
24743 Common index properties are listed in
24744 <xref linkend="functions-info-index-props"/>.
24745 (Note that extension access methods can define additional property
24746 names for their indexes.)
24747 <literal>NULL</literal> is returned if the property name is not known
24748 or does not apply to the particular object, or if the OID does not
24749 identify a valid object.
24750 </para></entry>
24751 </row>
24753 <row>
24754 <entry role="func_table_entry"><para role="func_signature">
24755 <indexterm>
24756 <primary>pg_indexam_has_property</primary>
24757 </indexterm>
24758 <function>pg_indexam_has_property</function> ( <parameter>am</parameter> <type>oid</type>, <parameter>property</parameter> <type>text</type> )
24759 <returnvalue>boolean</returnvalue>
24760 </para>
24761 <para>
24762 Tests whether an index access method has the named property.
24763 Access method properties are listed in
24764 <xref linkend="functions-info-indexam-props"/>.
24765 <literal>NULL</literal> is returned if the property name is not known
24766 or does not apply to the particular object, or if the OID does not
24767 identify a valid object.
24768 </para></entry>
24769 </row>
24771 <row>
24772 <entry role="func_table_entry"><para role="func_signature">
24773 <indexterm>
24774 <primary>pg_options_to_table</primary>
24775 </indexterm>
24776 <function>pg_options_to_table</function> ( <parameter>options_array</parameter> <type>text[]</type> )
24777 <returnvalue>setof record</returnvalue>
24778 ( <parameter>option_name</parameter> <type>text</type>,
24779 <parameter>option_value</parameter> <type>text</type> )
24780 </para>
24781 <para>
24782 Returns the set of storage options represented by a value from
24783 <structname>pg_class</structname>.<structfield>reloptions</structfield> or
24784 <structname>pg_attribute</structname>.<structfield>attoptions</structfield>.
24785 </para></entry>
24786 </row>
24788 <row>
24789 <entry role="func_table_entry"><para role="func_signature">
24790 <indexterm>
24791 <primary>pg_settings_get_flags</primary>
24792 </indexterm>
24793 <function>pg_settings_get_flags</function> ( <parameter>guc</parameter> <type>text</type> )
24794 <returnvalue>text[]</returnvalue>
24795 </para>
24796 <para>
24797 Returns an array of the flags associated with the given GUC, or
24798 <literal>NULL</literal> if it does not exist. The result is
24799 an empty array if the GUC exists but there are no flags to show.
24800 Only the most useful flags listed in
24801 <xref linkend="functions-pg-settings-flags"/> are exposed.
24802 </para></entry>
24803 </row>
24805 <row>
24806 <entry role="func_table_entry"><para role="func_signature">
24807 <indexterm>
24808 <primary>pg_tablespace_databases</primary>
24809 </indexterm>
24810 <function>pg_tablespace_databases</function> ( <parameter>tablespace</parameter> <type>oid</type> )
24811 <returnvalue>setof oid</returnvalue>
24812 </para>
24813 <para>
24814 Returns the set of OIDs of databases that have objects stored in the
24815 specified tablespace. If this function returns any rows, the
24816 tablespace is not empty and cannot be dropped. To identify the specific
24817 objects populating the tablespace, you will need to connect to the
24818 database(s) identified by <function>pg_tablespace_databases</function>
24819 and query their <structname>pg_class</structname> catalogs.
24820 </para></entry>
24821 </row>
24823 <row>
24824 <entry role="func_table_entry"><para role="func_signature">
24825 <indexterm>
24826 <primary>pg_tablespace_location</primary>
24827 </indexterm>
24828 <function>pg_tablespace_location</function> ( <parameter>tablespace</parameter> <type>oid</type> )
24829 <returnvalue>text</returnvalue>
24830 </para>
24831 <para>
24832 Returns the file system path that this tablespace is located in.
24833 </para></entry>
24834 </row>
24836 <row>
24837 <entry role="func_table_entry"><para role="func_signature">
24838 <indexterm>
24839 <primary>pg_typeof</primary>
24840 </indexterm>
24841 <function>pg_typeof</function> ( <type>"any"</type> )
24842 <returnvalue>regtype</returnvalue>
24843 </para>
24844 <para>
24845 Returns the OID of the data type of the value that is passed to it.
24846 This can be helpful for troubleshooting or dynamically constructing
24847 SQL queries. The function is declared as
24848 returning <type>regtype</type>, which is an OID alias type (see
24849 <xref linkend="datatype-oid"/>); this means that it is the same as an
24850 OID for comparison purposes but displays as a type name.
24851 </para>
24852 <para>
24853 For example:
24854 <programlisting>
24855 SELECT pg_typeof(33);
24856 pg_typeof
24857 -----------
24858 integer
24860 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
24861 typlen
24862 --------
24864 </programlisting>
24865 </para></entry>
24866 </row>
24868 <row>
24869 <entry role="func_table_entry"><para role="func_signature">
24870 <indexterm>
24871 <primary>COLLATION FOR</primary>
24872 </indexterm>
24873 <function>COLLATION FOR</function> ( <type>"any"</type> )
24874 <returnvalue>text</returnvalue>
24875 </para>
24876 <para>
24877 Returns the name of the collation of the value that is passed to it.
24878 The value is quoted and schema-qualified if necessary. If no
24879 collation was derived for the argument expression,
24880 then <literal>NULL</literal> is returned. If the argument is not of a
24881 collatable data type, then an error is raised.
24882 </para>
24883 <para>
24884 For example:
24885 <programlisting>
24886 SELECT collation for (description) FROM pg_description LIMIT 1;
24887 pg_collation_for
24888 ------------------
24889 "default"
24891 SELECT collation for ('foo' COLLATE "de_DE");
24892 pg_collation_for
24893 ------------------
24894 "de_DE"
24895 </programlisting>
24896 </para></entry>
24897 </row>
24899 <row>
24900 <entry role="func_table_entry"><para role="func_signature">
24901 <indexterm>
24902 <primary>to_regclass</primary>
24903 </indexterm>
24904 <function>to_regclass</function> ( <type>text</type> )
24905 <returnvalue>regclass</returnvalue>
24906 </para>
24907 <para>
24908 Translates a textual relation name to its OID. A similar result is
24909 obtained by casting the string to type <type>regclass</type> (see
24910 <xref linkend="datatype-oid"/>); however, this function will return
24911 <literal>NULL</literal> rather than throwing an error if the name is
24912 not found.
24913 </para></entry>
24914 </row>
24916 <row>
24917 <entry role="func_table_entry"><para role="func_signature">
24918 <indexterm>
24919 <primary>to_regcollation</primary>
24920 </indexterm>
24921 <function>to_regcollation</function> ( <type>text</type> )
24922 <returnvalue>regcollation</returnvalue>
24923 </para>
24924 <para>
24925 Translates a textual collation name to its OID. A similar result is
24926 obtained by casting the string to type <type>regcollation</type> (see
24927 <xref linkend="datatype-oid"/>); however, this function will return
24928 <literal>NULL</literal> rather than throwing an error if the name is
24929 not found.
24930 </para></entry>
24931 </row>
24933 <row>
24934 <entry role="func_table_entry"><para role="func_signature">
24935 <indexterm>
24936 <primary>to_regnamespace</primary>
24937 </indexterm>
24938 <function>to_regnamespace</function> ( <type>text</type> )
24939 <returnvalue>regnamespace</returnvalue>
24940 </para>
24941 <para>
24942 Translates a textual schema name to its OID. A similar result is
24943 obtained by casting the string to type <type>regnamespace</type> (see
24944 <xref linkend="datatype-oid"/>); however, this function will return
24945 <literal>NULL</literal> rather than throwing an error if the name is
24946 not found.
24947 </para></entry>
24948 </row>
24950 <row>
24951 <entry role="func_table_entry"><para role="func_signature">
24952 <indexterm>
24953 <primary>to_regoper</primary>
24954 </indexterm>
24955 <function>to_regoper</function> ( <type>text</type> )
24956 <returnvalue>regoper</returnvalue>
24957 </para>
24958 <para>
24959 Translates a textual operator name to its OID. A similar result is
24960 obtained by casting the string to type <type>regoper</type> (see
24961 <xref linkend="datatype-oid"/>); however, this function will return
24962 <literal>NULL</literal> rather than throwing an error if the name is
24963 not found or is ambiguous.
24964 </para></entry>
24965 </row>
24967 <row>
24968 <entry role="func_table_entry"><para role="func_signature">
24969 <indexterm>
24970 <primary>to_regoperator</primary>
24971 </indexterm>
24972 <function>to_regoperator</function> ( <type>text</type> )
24973 <returnvalue>regoperator</returnvalue>
24974 </para>
24975 <para>
24976 Translates a textual operator name (with parameter types) to its OID. A similar result is
24977 obtained by casting the string to type <type>regoperator</type> (see
24978 <xref linkend="datatype-oid"/>); however, this function will return
24979 <literal>NULL</literal> rather than throwing an error if the name is
24980 not found.
24981 </para></entry>
24982 </row>
24984 <row>
24985 <entry role="func_table_entry"><para role="func_signature">
24986 <indexterm>
24987 <primary>to_regproc</primary>
24988 </indexterm>
24989 <function>to_regproc</function> ( <type>text</type> )
24990 <returnvalue>regproc</returnvalue>
24991 </para>
24992 <para>
24993 Translates a textual function or procedure name to its OID. A similar result is
24994 obtained by casting the string to type <type>regproc</type> (see
24995 <xref linkend="datatype-oid"/>); however, this function will return
24996 <literal>NULL</literal> rather than throwing an error if the name is
24997 not found or is ambiguous.
24998 </para></entry>
24999 </row>
25001 <row>
25002 <entry role="func_table_entry"><para role="func_signature">
25003 <indexterm>
25004 <primary>to_regprocedure</primary>
25005 </indexterm>
25006 <function>to_regprocedure</function> ( <type>text</type> )
25007 <returnvalue>regprocedure</returnvalue>
25008 </para>
25009 <para>
25010 Translates a textual function or procedure name (with argument types) to its OID. A similar result is
25011 obtained by casting the string to type <type>regprocedure</type> (see
25012 <xref linkend="datatype-oid"/>); however, this function will return
25013 <literal>NULL</literal> rather than throwing an error if the name is
25014 not found.
25015 </para></entry>
25016 </row>
25018 <row>
25019 <entry role="func_table_entry"><para role="func_signature">
25020 <indexterm>
25021 <primary>to_regrole</primary>
25022 </indexterm>
25023 <function>to_regrole</function> ( <type>text</type> )
25024 <returnvalue>regrole</returnvalue>
25025 </para>
25026 <para>
25027 Translates a textual role name to its OID. A similar result is
25028 obtained by casting the string to type <type>regrole</type> (see
25029 <xref linkend="datatype-oid"/>); however, this function will return
25030 <literal>NULL</literal> rather than throwing an error if the name is
25031 not found.
25032 </para></entry>
25033 </row>
25035 <row>
25036 <entry role="func_table_entry"><para role="func_signature">
25037 <indexterm>
25038 <primary>to_regtype</primary>
25039 </indexterm>
25040 <function>to_regtype</function> ( <type>text</type> )
25041 <returnvalue>regtype</returnvalue>
25042 </para>
25043 <para>
25044 Translates a textual type name to its OID. A similar result is
25045 obtained by casting the string to type <type>regtype</type> (see
25046 <xref linkend="datatype-oid"/>); however, this function will return
25047 <literal>NULL</literal> rather than throwing an error if the name is
25048 not found.
25049 </para></entry>
25050 </row>
25051 </tbody>
25052 </tgroup>
25053 </table>
25055 <para>
25056 Most of the functions that reconstruct (decompile) database objects
25057 have an optional <parameter>pretty</parameter> flag, which
25058 if <literal>true</literal> causes the result to
25059 be <quote>pretty-printed</quote>. Pretty-printing suppresses unnecessary
25060 parentheses and adds whitespace for legibility.
25061 The pretty-printed format is more readable, but the default format
25062 is more likely to be interpreted the same way by future versions of
25063 <productname>PostgreSQL</productname>; so avoid using pretty-printed output
25064 for dump purposes. Passing <literal>false</literal> for
25065 the <parameter>pretty</parameter> parameter yields the same result as
25066 omitting the parameter.
25067 </para>
25069 <table id="functions-info-index-column-props">
25070 <title>Index Column Properties</title>
25071 <tgroup cols="2">
25072 <thead>
25073 <row><entry>Name</entry><entry>Description</entry></row>
25074 </thead>
25075 <tbody>
25076 <row>
25077 <entry><literal>asc</literal></entry>
25078 <entry>Does the column sort in ascending order on a forward scan?
25079 </entry>
25080 </row>
25081 <row>
25082 <entry><literal>desc</literal></entry>
25083 <entry>Does the column sort in descending order on a forward scan?
25084 </entry>
25085 </row>
25086 <row>
25087 <entry><literal>nulls_first</literal></entry>
25088 <entry>Does the column sort with nulls first on a forward scan?
25089 </entry>
25090 </row>
25091 <row>
25092 <entry><literal>nulls_last</literal></entry>
25093 <entry>Does the column sort with nulls last on a forward scan?
25094 </entry>
25095 </row>
25096 <row>
25097 <entry><literal>orderable</literal></entry>
25098 <entry>Does the column possess any defined sort ordering?
25099 </entry>
25100 </row>
25101 <row>
25102 <entry><literal>distance_orderable</literal></entry>
25103 <entry>Can the column be scanned in order by a <quote>distance</quote>
25104 operator, for example <literal>ORDER BY col &lt;-&gt; constant</literal> ?
25105 </entry>
25106 </row>
25107 <row>
25108 <entry><literal>returnable</literal></entry>
25109 <entry>Can the column value be returned by an index-only scan?
25110 </entry>
25111 </row>
25112 <row>
25113 <entry><literal>search_array</literal></entry>
25114 <entry>Does the column natively support <literal>col = ANY(array)</literal>
25115 searches?
25116 </entry>
25117 </row>
25118 <row>
25119 <entry><literal>search_nulls</literal></entry>
25120 <entry>Does the column support <literal>IS NULL</literal> and
25121 <literal>IS NOT NULL</literal> searches?
25122 </entry>
25123 </row>
25124 </tbody>
25125 </tgroup>
25126 </table>
25128 <table id="functions-info-index-props">
25129 <title>Index Properties</title>
25130 <tgroup cols="2">
25131 <thead>
25132 <row><entry>Name</entry><entry>Description</entry></row>
25133 </thead>
25134 <tbody>
25135 <row>
25136 <entry><literal>clusterable</literal></entry>
25137 <entry>Can the index be used in a <literal>CLUSTER</literal> command?
25138 </entry>
25139 </row>
25140 <row>
25141 <entry><literal>index_scan</literal></entry>
25142 <entry>Does the index support plain (non-bitmap) scans?
25143 </entry>
25144 </row>
25145 <row>
25146 <entry><literal>bitmap_scan</literal></entry>
25147 <entry>Does the index support bitmap scans?
25148 </entry>
25149 </row>
25150 <row>
25151 <entry><literal>backward_scan</literal></entry>
25152 <entry>Can the scan direction be changed in mid-scan (to
25153 support <literal>FETCH BACKWARD</literal> on a cursor without
25154 needing materialization)?
25155 </entry>
25156 </row>
25157 </tbody>
25158 </tgroup>
25159 </table>
25161 <table id="functions-info-indexam-props">
25162 <title>Index Access Method Properties</title>
25163 <tgroup cols="2">
25164 <thead>
25165 <row><entry>Name</entry><entry>Description</entry></row>
25166 </thead>
25167 <tbody>
25168 <row>
25169 <entry><literal>can_order</literal></entry>
25170 <entry>Does the access method support <literal>ASC</literal>,
25171 <literal>DESC</literal> and related keywords in
25172 <literal>CREATE INDEX</literal>?
25173 </entry>
25174 </row>
25175 <row>
25176 <entry><literal>can_unique</literal></entry>
25177 <entry>Does the access method support unique indexes?
25178 </entry>
25179 </row>
25180 <row>
25181 <entry><literal>can_multi_col</literal></entry>
25182 <entry>Does the access method support indexes with multiple columns?
25183 </entry>
25184 </row>
25185 <row>
25186 <entry><literal>can_exclude</literal></entry>
25187 <entry>Does the access method support exclusion constraints?
25188 </entry>
25189 </row>
25190 <row>
25191 <entry><literal>can_include</literal></entry>
25192 <entry>Does the access method support the <literal>INCLUDE</literal>
25193 clause of <literal>CREATE INDEX</literal>?
25194 </entry>
25195 </row>
25196 </tbody>
25197 </tgroup>
25198 </table>
25200 <table id="functions-pg-settings-flags">
25201 <title>GUC Flags</title>
25202 <tgroup cols="2">
25203 <thead>
25204 <row><entry>Flag</entry><entry>Description</entry></row>
25205 </thead>
25206 <tbody>
25207 <row>
25208 <entry><literal>EXPLAIN</literal></entry>
25209 <entry>Parameters with this flag are included in
25210 <command>EXPLAIN (SETTINGS)</command> commands.
25211 </entry>
25212 </row>
25213 <row>
25214 <entry><literal>NO_SHOW_ALL</literal></entry>
25215 <entry>Parameters with this flag are excluded from
25216 <command>SHOW ALL</command> commands.
25217 </entry>
25218 </row>
25219 <row>
25220 <entry><literal>NO_RESET</literal></entry>
25221 <entry>Parameters with this flag do not support
25222 <command>RESET</command> commands.
25223 </entry>
25224 </row>
25225 <row>
25226 <entry><literal>NO_RESET_ALL</literal></entry>
25227 <entry>Parameters with this flag are excluded from
25228 <command>RESET ALL</command> commands.
25229 </entry>
25230 </row>
25231 <row>
25232 <entry><literal>NOT_IN_SAMPLE</literal></entry>
25233 <entry>Parameters with this flag are not included in
25234 <filename>postgresql.conf</filename> by default.
25235 </entry>
25236 </row>
25237 <row>
25238 <entry><literal>RUNTIME_COMPUTED</literal></entry>
25239 <entry>Parameters with this flag are runtime-computed ones.
25240 </entry>
25241 </row>
25242 </tbody>
25243 </tgroup>
25244 </table>
25246 </sect2>
25248 <sect2 id="functions-info-object">
25249 <title>Object Information and Addressing Functions</title>
25251 <para>
25252 <xref linkend="functions-info-object-table"/> lists functions related to
25253 database object identification and addressing.
25254 </para>
25256 <table id="functions-info-object-table">
25257 <title>Object Information and Addressing Functions</title>
25258 <tgroup cols="1">
25259 <thead>
25260 <row>
25261 <entry role="func_table_entry"><para role="func_signature">
25262 Function
25263 </para>
25264 <para>
25265 Description
25266 </para></entry>
25267 </row>
25268 </thead>
25270 <tbody>
25271 <row>
25272 <entry role="func_table_entry"><para role="func_signature">
25273 <indexterm>
25274 <primary>pg_describe_object</primary>
25275 </indexterm>
25276 <function>pg_describe_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
25277 <returnvalue>text</returnvalue>
25278 </para>
25279 <para>
25280 Returns a textual description of a database object identified by
25281 catalog OID, object OID, and sub-object ID (such as a column number
25282 within a table; the sub-object ID is zero when referring to a whole
25283 object). This description is intended to be human-readable, and might
25284 be translated, depending on server configuration. This is especially
25285 useful to determine the identity of an object referenced in the
25286 <structname>pg_depend</structname> catalog. This function returns
25287 <literal>NULL</literal> values for undefined objects.
25288 </para></entry>
25289 </row>
25291 <row>
25292 <entry role="func_table_entry"><para role="func_signature">
25293 <indexterm>
25294 <primary>pg_identify_object</primary>
25295 </indexterm>
25296 <function>pg_identify_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
25297 <returnvalue>record</returnvalue>
25298 ( <parameter>type</parameter> <type>text</type>,
25299 <parameter>schema</parameter> <type>text</type>,
25300 <parameter>name</parameter> <type>text</type>,
25301 <parameter>identity</parameter> <type>text</type> )
25302 </para>
25303 <para>
25304 Returns a row containing enough information to uniquely identify the
25305 database object specified by catalog OID, object OID and sub-object
25307 This information is intended to be machine-readable, and is never
25308 translated.
25309 <parameter>type</parameter> identifies the type of database object;
25310 <parameter>schema</parameter> is the schema name that the object
25311 belongs in, or <literal>NULL</literal> for object types that do not
25312 belong to schemas;
25313 <parameter>name</parameter> is the name of the object, quoted if
25314 necessary, if the name (along with schema name, if pertinent) is
25315 sufficient to uniquely identify the object,
25316 otherwise <literal>NULL</literal>;
25317 <parameter>identity</parameter> is the complete object identity, with
25318 the precise format depending on object type, and each name within the
25319 format being schema-qualified and quoted as necessary. Undefined
25320 objects are identified with <literal>NULL</literal> values.
25321 </para></entry>
25322 </row>
25324 <row>
25325 <entry role="func_table_entry"><para role="func_signature">
25326 <indexterm>
25327 <primary>pg_identify_object_as_address</primary>
25328 </indexterm>
25329 <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> )
25330 <returnvalue>record</returnvalue>
25331 ( <parameter>type</parameter> <type>text</type>,
25332 <parameter>object_names</parameter> <type>text[]</type>,
25333 <parameter>object_args</parameter> <type>text[]</type> )
25334 </para>
25335 <para>
25336 Returns a row containing enough information to uniquely identify the
25337 database object specified by catalog OID, object OID and sub-object
25339 The returned information is independent of the current server, that
25340 is, it could be used to identify an identically named object in
25341 another server.
25342 <parameter>type</parameter> identifies the type of database object;
25343 <parameter>object_names</parameter> and
25344 <parameter>object_args</parameter>
25345 are text arrays that together form a reference to the object.
25346 These three values can be passed
25347 to <function>pg_get_object_address</function> to obtain the internal
25348 address of the object.
25349 </para></entry>
25350 </row>
25352 <row>
25353 <entry role="func_table_entry"><para role="func_signature">
25354 <indexterm>
25355 <primary>pg_get_object_address</primary>
25356 </indexterm>
25357 <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> )
25358 <returnvalue>record</returnvalue>
25359 ( <parameter>classid</parameter> <type>oid</type>,
25360 <parameter>objid</parameter> <type>oid</type>,
25361 <parameter>objsubid</parameter> <type>integer</type> )
25362 </para>
25363 <para>
25364 Returns a row containing enough information to uniquely identify the
25365 database object specified by a type code and object name and argument
25366 arrays.
25367 The returned values are the ones that would be used in system catalogs
25368 such as <structname>pg_depend</structname>; they can be passed to
25369 other system functions such as <function>pg_describe_object</function>
25370 or <function>pg_identify_object</function>.
25371 <parameter>classid</parameter> is the OID of the system catalog
25372 containing the object;
25373 <parameter>objid</parameter> is the OID of the object itself, and
25374 <parameter>objsubid</parameter> is the sub-object ID, or zero if none.
25375 This function is the inverse
25376 of <function>pg_identify_object_as_address</function>.
25377 Undefined objects are identified with <literal>NULL</literal> values.
25378 </para></entry>
25379 </row>
25380 </tbody>
25381 </tgroup>
25382 </table>
25384 </sect2>
25386 <sect2 id="functions-info-comment">
25387 <title>Comment Information Functions</title>
25389 <indexterm>
25390 <primary>comment</primary>
25391 <secondary sortas="database objects">about database objects</secondary>
25392 </indexterm>
25394 <para>
25395 The functions shown in <xref linkend="functions-info-comment-table"/>
25396 extract comments previously stored with the <xref linkend="sql-comment"/>
25397 command. A null value is returned if no
25398 comment could be found for the specified parameters.
25399 </para>
25401 <table id="functions-info-comment-table">
25402 <title>Comment Information Functions</title>
25403 <tgroup cols="1">
25404 <thead>
25405 <row>
25406 <entry role="func_table_entry"><para role="func_signature">
25407 Function
25408 </para>
25409 <para>
25410 Description
25411 </para></entry>
25412 </row>
25413 </thead>
25415 <tbody>
25416 <row>
25417 <entry role="func_table_entry"><para role="func_signature">
25418 <indexterm>
25419 <primary>col_description</primary>
25420 </indexterm>
25421 <function>col_description</function> ( <parameter>table</parameter> <type>oid</type>, <parameter>column</parameter> <type>integer</type> )
25422 <returnvalue>text</returnvalue>
25423 </para>
25424 <para>
25425 Returns the comment for a table column, which is specified by the OID
25426 of its table and its column number.
25427 (<function>obj_description</function> cannot be used for table
25428 columns, since columns do not have OIDs of their own.)
25429 </para></entry>
25430 </row>
25432 <row>
25433 <entry role="func_table_entry"><para role="func_signature">
25434 <indexterm>
25435 <primary>obj_description</primary>
25436 </indexterm>
25437 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
25438 <returnvalue>text</returnvalue>
25439 </para>
25440 <para>
25441 Returns the comment for a database object specified by its OID and the
25442 name of the containing system catalog. For
25443 example, <literal>obj_description(123456, 'pg_class')</literal> would
25444 retrieve the comment for the table with OID 123456.
25445 </para></entry>
25446 </row>
25448 <row>
25449 <entry role="func_table_entry"><para role="func_signature">
25450 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type> )
25451 <returnvalue>text</returnvalue>
25452 </para>
25453 <para>
25454 Returns the comment for a database object specified by its OID alone.
25455 This is <emphasis>deprecated</emphasis> since there is no guarantee
25456 that OIDs are unique across different system catalogs; therefore, the
25457 wrong comment might be returned.
25458 </para></entry>
25459 </row>
25461 <row>
25462 <entry role="func_table_entry"><para role="func_signature">
25463 <indexterm>
25464 <primary>shobj_description</primary>
25465 </indexterm>
25466 <function>shobj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
25467 <returnvalue>text</returnvalue>
25468 </para>
25469 <para>
25470 Returns the comment for a shared database object specified by its OID
25471 and the name of the containing system catalog. This is just
25472 like <function>obj_description</function> except that it is used for
25473 retrieving comments on shared objects (that is, databases, roles, and
25474 tablespaces). Some system catalogs are global to all databases within
25475 each cluster, and the descriptions for objects in them are stored
25476 globally as well.
25477 </para></entry>
25478 </row>
25479 </tbody>
25480 </tgroup>
25481 </table>
25483 </sect2>
25485 <sect2 id="functions-info-validity">
25486 <title>Data Validity Checking Functions</title>
25488 <para>
25489 The functions shown in <xref linkend="functions-info-validity-table"/>
25490 can be helpful for checking validity of proposed input data.
25491 </para>
25493 <table id="functions-info-validity-table">
25494 <title>Data Validity Checking Functions</title>
25495 <tgroup cols="1">
25496 <thead>
25497 <row>
25498 <entry role="func_table_entry"><para role="func_signature">
25499 Function
25500 </para>
25501 <para>
25502 Description
25503 </para>
25504 <para>
25505 Example(s)
25506 </para></entry>
25507 </row>
25508 </thead>
25510 <tbody>
25511 <row>
25512 <entry role="func_table_entry"><para role="func_signature">
25513 <indexterm>
25514 <primary>pg_input_is_valid</primary>
25515 </indexterm>
25516 <function>pg_input_is_valid</function> (
25517 <parameter>string</parameter> <type>text</type>,
25518 <parameter>type</parameter> <type>text</type>
25520 <returnvalue>boolean</returnvalue>
25521 </para>
25522 <para>
25523 Tests whether the given <parameter>string</parameter> is valid
25524 input for the specified data type, returning true or false.
25525 </para>
25526 <para>
25527 This function will only work as desired if the data type's input
25528 function has been updated to report invalid input as
25529 a <quote>soft</quote> error. Otherwise, invalid input will abort
25530 the transaction, just as if the string had been cast to the type
25531 directly.
25532 </para>
25533 <para>
25534 <literal>pg_input_is_valid('42', 'integer')</literal>
25535 <returnvalue>t</returnvalue>
25536 </para>
25537 <para>
25538 <literal>pg_input_is_valid('42000000000', 'integer')</literal>
25539 <returnvalue>f</returnvalue>
25540 </para>
25541 <para>
25542 <literal>pg_input_is_valid('1234.567', 'numeric(7,4)')</literal>
25543 <returnvalue>f</returnvalue>
25544 </para></entry>
25545 </row>
25546 <row>
25547 <entry role="func_table_entry"><para role="func_signature">
25548 <indexterm>
25549 <primary>pg_input_error_info</primary>
25550 </indexterm>
25551 <function>pg_input_error_info</function> (
25552 <parameter>string</parameter> <type>text</type>,
25553 <parameter>type</parameter> <type>text</type>
25555 <returnvalue>record</returnvalue>
25556 ( <parameter>message</parameter> <type>text</type>,
25557 <parameter>detail</parameter> <type>text</type>,
25558 <parameter>hint</parameter> <type>text</type>,
25559 <parameter>sql_error_code</parameter> <type>text</type> )
25560 </para>
25561 <para>
25562 Tests whether the given <parameter>string</parameter> is valid
25563 input for the specified data type; if not, return the details of
25564 the error that would have been thrown. If the input is valid, the
25565 results are NULL. The inputs are the same as
25566 for <function>pg_input_is_valid</function>.
25567 </para>
25568 <para>
25569 This function will only work as desired if the data type's input
25570 function has been updated to report invalid input as
25571 a <quote>soft</quote> error. Otherwise, invalid input will abort
25572 the transaction, just as if the string had been cast to the type
25573 directly.
25574 </para>
25575 <para>
25576 <literal>select * from pg_input_error_info('42000000000', 'integer')</literal>
25577 <returnvalue></returnvalue>
25578 <programlisting>
25579 message | detail | hint | sql_error_code
25580 ------------------------------------------------------+--------+------+----------------
25581 value "42000000000" is out of range for type integer | | | 22003
25582 </programlisting>
25583 </para>
25584 <para>
25585 <literal>select message, detail from pg_input_error_info('1234.567', 'numeric(7,4)')</literal>
25586 <returnvalue></returnvalue>
25587 <programlisting>
25588 message | detail
25589 ------------------------+----------------------------------&zwsp;-------------------------------------------------
25590 numeric field overflow | A field with precision 7, scale 4 must round to an absolute value less than 10^3.
25591 </programlisting>
25592 </para></entry>
25593 </row>
25594 </tbody>
25595 </tgroup>
25596 </table>
25598 </sect2>
25600 <sect2 id="functions-info-snapshot">
25601 <title>Transaction ID and Snapshot Information Functions</title>
25603 <para>
25604 The functions shown in <xref linkend="functions-pg-snapshot"/>
25605 provide server transaction information in an exportable form. The main
25606 use of these functions is to determine which transactions were committed
25607 between two snapshots.
25608 </para>
25610 <table id="functions-pg-snapshot">
25611 <title>Transaction ID and Snapshot Information Functions</title>
25612 <tgroup cols="1">
25613 <thead>
25614 <row>
25615 <entry role="func_table_entry"><para role="func_signature">
25616 Function
25617 </para>
25618 <para>
25619 Description
25620 </para></entry>
25621 </row>
25622 </thead>
25624 <tbody>
25625 <row>
25626 <entry role="func_table_entry"><para role="func_signature">
25627 <indexterm>
25628 <primary>pg_current_xact_id</primary>
25629 </indexterm>
25630 <function>pg_current_xact_id</function> ()
25631 <returnvalue>xid8</returnvalue>
25632 </para>
25633 <para>
25634 Returns the current transaction's ID. It will assign a new one if the
25635 current transaction does not have one already (because it has not
25636 performed any database updates); see <xref
25637 linkend="transaction-id"/> for details. If executed in a
25638 subtransaction, this will return the top-level transaction ID;
25639 see <xref linkend="subxacts"/> for details.
25640 </para></entry>
25641 </row>
25643 <row>
25644 <entry role="func_table_entry"><para role="func_signature">
25645 <indexterm>
25646 <primary>pg_current_xact_id_if_assigned</primary>
25647 </indexterm>
25648 <function>pg_current_xact_id_if_assigned</function> ()
25649 <returnvalue>xid8</returnvalue>
25650 </para>
25651 <para>
25652 Returns the current transaction's ID, or <literal>NULL</literal> if no
25653 ID is assigned yet. (It's best to use this variant if the transaction
25654 might otherwise be read-only, to avoid unnecessary consumption of an
25655 XID.)
25656 If executed in a subtransaction, this will return the top-level
25657 transaction ID.
25658 </para></entry>
25659 </row>
25661 <row>
25662 <entry role="func_table_entry"><para role="func_signature">
25663 <indexterm>
25664 <primary>pg_xact_status</primary>
25665 </indexterm>
25666 <function>pg_xact_status</function> ( <type>xid8</type> )
25667 <returnvalue>text</returnvalue>
25668 </para>
25669 <para>
25670 Reports the commit status of a recent transaction.
25671 The result is one of <literal>in progress</literal>,
25672 <literal>committed</literal>, or <literal>aborted</literal>,
25673 provided that the transaction is recent enough that the system retains
25674 the commit status of that transaction.
25675 If it is old enough that no references to the transaction survive in
25676 the system and the commit status information has been discarded, the
25677 result is <literal>NULL</literal>.
25678 Applications might use this function, for example, to determine
25679 whether their transaction committed or aborted after the application
25680 and database server become disconnected while
25681 a <literal>COMMIT</literal> is in progress.
25682 Note that prepared transactions are reported as <literal>in
25683 progress</literal>; applications must check <link
25684 linkend="view-pg-prepared-xacts"><structname>pg_prepared_xacts</structname></link>
25685 if they need to determine whether a transaction ID belongs to a
25686 prepared transaction.
25687 </para></entry>
25688 </row>
25690 <row>
25691 <entry role="func_table_entry"><para role="func_signature">
25692 <indexterm>
25693 <primary>pg_current_snapshot</primary>
25694 </indexterm>
25695 <function>pg_current_snapshot</function> ()
25696 <returnvalue>pg_snapshot</returnvalue>
25697 </para>
25698 <para>
25699 Returns a current <firstterm>snapshot</firstterm>, a data structure
25700 showing which transaction IDs are now in-progress.
25701 Only top-level transaction IDs are included in the snapshot;
25702 subtransaction IDs are not shown; see <xref linkend="subxacts"/>
25703 for details.
25704 </para></entry>
25705 </row>
25707 <row>
25708 <entry role="func_table_entry"><para role="func_signature">
25709 <indexterm>
25710 <primary>pg_snapshot_xip</primary>
25711 </indexterm>
25712 <function>pg_snapshot_xip</function> ( <type>pg_snapshot</type> )
25713 <returnvalue>setof xid8</returnvalue>
25714 </para>
25715 <para>
25716 Returns the set of in-progress transaction IDs contained in a snapshot.
25717 </para></entry>
25718 </row>
25720 <row>
25721 <entry role="func_table_entry"><para role="func_signature">
25722 <indexterm>
25723 <primary>pg_snapshot_xmax</primary>
25724 </indexterm>
25725 <function>pg_snapshot_xmax</function> ( <type>pg_snapshot</type> )
25726 <returnvalue>xid8</returnvalue>
25727 </para>
25728 <para>
25729 Returns the <structfield>xmax</structfield> of a snapshot.
25730 </para></entry>
25731 </row>
25733 <row>
25734 <entry role="func_table_entry"><para role="func_signature">
25735 <indexterm>
25736 <primary>pg_snapshot_xmin</primary>
25737 </indexterm>
25738 <function>pg_snapshot_xmin</function> ( <type>pg_snapshot</type> )
25739 <returnvalue>xid8</returnvalue>
25740 </para>
25741 <para>
25742 Returns the <structfield>xmin</structfield> of a snapshot.
25743 </para></entry>
25744 </row>
25746 <row>
25747 <entry role="func_table_entry"><para role="func_signature">
25748 <indexterm>
25749 <primary>pg_visible_in_snapshot</primary>
25750 </indexterm>
25751 <function>pg_visible_in_snapshot</function> ( <type>xid8</type>, <type>pg_snapshot</type> )
25752 <returnvalue>boolean</returnvalue>
25753 </para>
25754 <para>
25755 Is the given transaction ID <firstterm>visible</firstterm> according
25756 to this snapshot (that is, was it completed before the snapshot was
25757 taken)? Note that this function will not give the correct answer for
25758 a subtransaction ID (subxid); see <xref linkend="subxacts"/> for
25759 details.
25760 </para></entry>
25761 </row>
25762 </tbody>
25763 </tgroup>
25764 </table>
25766 <para>
25767 The internal transaction ID type <type>xid</type> is 32 bits wide and
25768 wraps around every 4 billion transactions. However,
25769 the functions shown in <xref linkend="functions-pg-snapshot"/> use a
25770 64-bit type <type>xid8</type> that does not wrap around during the life
25771 of an installation and can be converted to <type>xid</type> by casting if
25772 required; see <xref linkend="transaction-id"/> for details.
25773 The data type <type>pg_snapshot</type> stores information about
25774 transaction ID visibility at a particular moment in time. Its components
25775 are described in <xref linkend="functions-pg-snapshot-parts"/>.
25776 <type>pg_snapshot</type>'s textual representation is
25777 <literal><replaceable>xmin</replaceable>:<replaceable>xmax</replaceable>:<replaceable>xip_list</replaceable></literal>.
25778 For example <literal>10:20:10,14,15</literal> means
25779 <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
25780 </para>
25782 <table id="functions-pg-snapshot-parts">
25783 <title>Snapshot Components</title>
25784 <tgroup cols="2">
25785 <thead>
25786 <row>
25787 <entry>Name</entry>
25788 <entry>Description</entry>
25789 </row>
25790 </thead>
25792 <tbody>
25793 <row>
25794 <entry><structfield>xmin</structfield></entry>
25795 <entry>
25796 Lowest transaction ID that was still active. All transaction IDs
25797 less than <structfield>xmin</structfield> are either committed and visible,
25798 or rolled back and dead.
25799 </entry>
25800 </row>
25802 <row>
25803 <entry><structfield>xmax</structfield></entry>
25804 <entry>
25805 One past the highest completed transaction ID. All transaction IDs
25806 greater than or equal to <structfield>xmax</structfield> had not yet
25807 completed as of the time of the snapshot, and thus are invisible.
25808 </entry>
25809 </row>
25811 <row>
25812 <entry><structfield>xip_list</structfield></entry>
25813 <entry>
25814 Transactions in progress at the time of the snapshot. A transaction
25815 ID that is <literal>xmin &lt;= <replaceable>X</replaceable> &lt;
25816 xmax</literal> and not in this list was already completed at the time
25817 of the snapshot, and thus is either visible or dead according to its
25818 commit status. This list does not include the transaction IDs of
25819 subtransactions (subxids).
25820 </entry>
25821 </row>
25822 </tbody>
25823 </tgroup>
25824 </table>
25826 <para>
25827 In releases of <productname>PostgreSQL</productname> before 13 there was
25828 no <type>xid8</type> type, so variants of these functions were provided
25829 that used <type>bigint</type> to represent a 64-bit XID, with a
25830 correspondingly distinct snapshot data type <type>txid_snapshot</type>.
25831 These older functions have <literal>txid</literal> in their names. They
25832 are still supported for backward compatibility, but may be removed from a
25833 future release. See <xref linkend="functions-txid-snapshot"/>.
25834 </para>
25836 <table id="functions-txid-snapshot">
25837 <title>Deprecated Transaction ID and Snapshot Information Functions</title>
25838 <tgroup cols="1">
25839 <thead>
25840 <row>
25841 <entry role="func_table_entry"><para role="func_signature">
25842 Function
25843 </para>
25844 <para>
25845 Description
25846 </para></entry>
25847 </row>
25848 </thead>
25850 <tbody>
25851 <row>
25852 <entry role="func_table_entry"><para role="func_signature">
25853 <indexterm>
25854 <primary>age</primary>
25855 </indexterm>
25856 <function>age</function> ( <type>xid</type> )
25857 <returnvalue>integer</returnvalue>
25858 </para>
25859 <para>
25860 Returns the number of transactions between the supplied
25861 transaction id and the current transaction counter.
25862 </para></entry>
25863 </row>
25865 <row>
25866 <entry role="func_table_entry"><para role="func_signature">
25867 <indexterm>
25868 <primary>mxid_age</primary>
25869 </indexterm>
25870 <function>mxid_age</function> ( <type>xid</type> )
25871 <returnvalue>integer</returnvalue>
25872 </para>
25873 <para>
25874 Returns the number of multixacts IDs between the supplied
25875 multixact ID and the current multixacts counter.
25876 </para></entry>
25877 </row>
25879 <row>
25880 <entry role="func_table_entry"><para role="func_signature">
25881 <indexterm>
25882 <primary>txid_current</primary>
25883 </indexterm>
25884 <function>txid_current</function> ()
25885 <returnvalue>bigint</returnvalue>
25886 </para>
25887 <para>
25888 See <function>pg_current_xact_id()</function>.
25889 </para></entry>
25890 </row>
25892 <row>
25893 <entry role="func_table_entry"><para role="func_signature">
25894 <indexterm>
25895 <primary>txid_current_if_assigned</primary>
25896 </indexterm>
25897 <function>txid_current_if_assigned</function> ()
25898 <returnvalue>bigint</returnvalue>
25899 </para>
25900 <para>
25901 See <function>pg_current_xact_id_if_assigned()</function>.
25902 </para></entry>
25903 </row>
25905 <row>
25906 <entry role="func_table_entry"><para role="func_signature">
25907 <indexterm>
25908 <primary>txid_current_snapshot</primary>
25909 </indexterm>
25910 <function>txid_current_snapshot</function> ()
25911 <returnvalue>txid_snapshot</returnvalue>
25912 </para>
25913 <para>
25914 See <function>pg_current_snapshot()</function>.
25915 </para></entry>
25916 </row>
25918 <row>
25919 <entry role="func_table_entry"><para role="func_signature">
25920 <indexterm>
25921 <primary>txid_snapshot_xip</primary>
25922 </indexterm>
25923 <function>txid_snapshot_xip</function> ( <type>txid_snapshot</type> )
25924 <returnvalue>setof bigint</returnvalue>
25925 </para>
25926 <para>
25927 See <function>pg_snapshot_xip()</function>.
25928 </para></entry>
25929 </row>
25931 <row>
25932 <entry role="func_table_entry"><para role="func_signature">
25933 <indexterm>
25934 <primary>txid_snapshot_xmax</primary>
25935 </indexterm>
25936 <function>txid_snapshot_xmax</function> ( <type>txid_snapshot</type> )
25937 <returnvalue>bigint</returnvalue>
25938 </para>
25939 <para>
25940 See <function>pg_snapshot_xmax()</function>.
25941 </para></entry>
25942 </row>
25944 <row>
25945 <entry role="func_table_entry"><para role="func_signature">
25946 <indexterm>
25947 <primary>txid_snapshot_xmin</primary>
25948 </indexterm>
25949 <function>txid_snapshot_xmin</function> ( <type>txid_snapshot</type> )
25950 <returnvalue>bigint</returnvalue>
25951 </para>
25952 <para>
25953 See <function>pg_snapshot_xmin()</function>.
25954 </para></entry>
25955 </row>
25957 <row>
25958 <entry role="func_table_entry"><para role="func_signature">
25959 <indexterm>
25960 <primary>txid_visible_in_snapshot</primary>
25961 </indexterm>
25962 <function>txid_visible_in_snapshot</function> ( <type>bigint</type>, <type>txid_snapshot</type> )
25963 <returnvalue>boolean</returnvalue>
25964 </para>
25965 <para>
25966 See <function>pg_visible_in_snapshot()</function>.
25967 </para></entry>
25968 </row>
25970 <row>
25971 <entry role="func_table_entry"><para role="func_signature">
25972 <indexterm>
25973 <primary>txid_status</primary>
25974 </indexterm>
25975 <function>txid_status</function> ( <type>bigint</type> )
25976 <returnvalue>text</returnvalue>
25977 </para>
25978 <para>
25979 See <function>pg_xact_status()</function>.
25980 </para></entry>
25981 </row>
25982 </tbody>
25983 </tgroup>
25984 </table>
25986 </sect2>
25988 <sect2 id="functions-info-commit-timestamp">
25989 <title>Committed Transaction Information Functions</title>
25991 <para>
25992 The functions shown in <xref linkend="functions-commit-timestamp"/>
25993 provide information about when past transactions were committed.
25994 They only provide useful data when the
25995 <xref linkend="guc-track-commit-timestamp"/> configuration option is
25996 enabled, and only for transactions that were committed after it was
25997 enabled. Commit timestamp information is routinely removed during
25998 vacuum.
25999 </para>
26001 <table id="functions-commit-timestamp">
26002 <title>Committed Transaction Information Functions</title>
26003 <tgroup cols="1">
26004 <thead>
26005 <row>
26006 <entry role="func_table_entry"><para role="func_signature">
26007 Function
26008 </para>
26009 <para>
26010 Description
26011 </para></entry>
26012 </row>
26013 </thead>
26015 <tbody>
26016 <row>
26017 <entry role="func_table_entry"><para role="func_signature">
26018 <indexterm>
26019 <primary>pg_xact_commit_timestamp</primary>
26020 </indexterm>
26021 <function>pg_xact_commit_timestamp</function> ( <type>xid</type> )
26022 <returnvalue>timestamp with time zone</returnvalue>
26023 </para>
26024 <para>
26025 Returns the commit timestamp of a transaction.
26026 </para></entry>
26027 </row>
26029 <row>
26030 <entry role="func_table_entry"><para role="func_signature">
26031 <indexterm>
26032 <primary>pg_xact_commit_timestamp_origin</primary>
26033 </indexterm>
26034 <function>pg_xact_commit_timestamp_origin</function> ( <type>xid</type> )
26035 <returnvalue>record</returnvalue>
26036 ( <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
26037 <parameter>roident</parameter> <type>oid</type>)
26038 </para>
26039 <para>
26040 Returns the commit timestamp and replication origin of a transaction.
26041 </para></entry>
26042 </row>
26044 <row>
26045 <entry role="func_table_entry"><para role="func_signature">
26046 <indexterm>
26047 <primary>pg_last_committed_xact</primary>
26048 </indexterm>
26049 <function>pg_last_committed_xact</function> ()
26050 <returnvalue>record</returnvalue>
26051 ( <parameter>xid</parameter> <type>xid</type>,
26052 <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
26053 <parameter>roident</parameter> <type>oid</type> )
26054 </para>
26055 <para>
26056 Returns the transaction ID, commit timestamp and replication origin
26057 of the latest committed transaction.
26058 </para></entry>
26059 </row>
26060 </tbody>
26061 </tgroup>
26062 </table>
26064 </sect2>
26066 <sect2 id="functions-info-controldata">
26067 <title>Control Data Functions</title>
26069 <para>
26070 The functions shown in <xref linkend="functions-controldata"/>
26071 print information initialized during <command>initdb</command>, such
26072 as the catalog version. They also show information about write-ahead
26073 logging and checkpoint processing. This information is cluster-wide,
26074 not specific to any one database. These functions provide most of the same
26075 information, from the same source, as the
26076 <xref linkend="app-pgcontroldata"/> application.
26077 </para>
26079 <table id="functions-controldata">
26080 <title>Control Data Functions</title>
26081 <tgroup cols="1">
26082 <thead>
26083 <row>
26084 <entry role="func_table_entry"><para role="func_signature">
26085 Function
26086 </para>
26087 <para>
26088 Description
26089 </para></entry>
26090 </row>
26091 </thead>
26093 <tbody>
26094 <row>
26095 <entry role="func_table_entry"><para role="func_signature">
26096 <indexterm>
26097 <primary>pg_control_checkpoint</primary>
26098 </indexterm>
26099 <function>pg_control_checkpoint</function> ()
26100 <returnvalue>record</returnvalue>
26101 </para>
26102 <para>
26103 Returns information about current checkpoint state, as shown in
26104 <xref linkend="functions-pg-control-checkpoint"/>.
26105 </para></entry>
26106 </row>
26108 <row>
26109 <entry role="func_table_entry"><para role="func_signature">
26110 <indexterm>
26111 <primary>pg_control_system</primary>
26112 </indexterm>
26113 <function>pg_control_system</function> ()
26114 <returnvalue>record</returnvalue>
26115 </para>
26116 <para>
26117 Returns information about current control file state, as shown in
26118 <xref linkend="functions-pg-control-system"/>.
26119 </para></entry>
26120 </row>
26122 <row>
26123 <entry role="func_table_entry"><para role="func_signature">
26124 <indexterm>
26125 <primary>pg_control_init</primary>
26126 </indexterm>
26127 <function>pg_control_init</function> ()
26128 <returnvalue>record</returnvalue>
26129 </para>
26130 <para>
26131 Returns information about cluster initialization state, as shown in
26132 <xref linkend="functions-pg-control-init"/>.
26133 </para></entry>
26134 </row>
26136 <row>
26137 <entry role="func_table_entry"><para role="func_signature">
26138 <indexterm>
26139 <primary>pg_control_recovery</primary>
26140 </indexterm>
26141 <function>pg_control_recovery</function> ()
26142 <returnvalue>record</returnvalue>
26143 </para>
26144 <para>
26145 Returns information about recovery state, as shown in
26146 <xref linkend="functions-pg-control-recovery"/>.
26147 </para></entry>
26148 </row>
26149 </tbody>
26150 </tgroup>
26151 </table>
26153 <table id="functions-pg-control-checkpoint">
26154 <title><function>pg_control_checkpoint</function> Output Columns</title>
26155 <tgroup cols="2">
26156 <thead>
26157 <row>
26158 <entry>Column Name</entry>
26159 <entry>Data Type</entry>
26160 </row>
26161 </thead>
26163 <tbody>
26165 <row>
26166 <entry><structfield>checkpoint_lsn</structfield></entry>
26167 <entry><type>pg_lsn</type></entry>
26168 </row>
26170 <row>
26171 <entry><structfield>redo_lsn</structfield></entry>
26172 <entry><type>pg_lsn</type></entry>
26173 </row>
26175 <row>
26176 <entry><structfield>redo_wal_file</structfield></entry>
26177 <entry><type>text</type></entry>
26178 </row>
26180 <row>
26181 <entry><structfield>timeline_id</structfield></entry>
26182 <entry><type>integer</type></entry>
26183 </row>
26185 <row>
26186 <entry><structfield>prev_timeline_id</structfield></entry>
26187 <entry><type>integer</type></entry>
26188 </row>
26190 <row>
26191 <entry><structfield>full_page_writes</structfield></entry>
26192 <entry><type>boolean</type></entry>
26193 </row>
26195 <row>
26196 <entry><structfield>next_xid</structfield></entry>
26197 <entry><type>text</type></entry>
26198 </row>
26200 <row>
26201 <entry><structfield>next_oid</structfield></entry>
26202 <entry><type>oid</type></entry>
26203 </row>
26205 <row>
26206 <entry><structfield>next_multixact_id</structfield></entry>
26207 <entry><type>xid</type></entry>
26208 </row>
26210 <row>
26211 <entry><structfield>next_multi_offset</structfield></entry>
26212 <entry><type>xid</type></entry>
26213 </row>
26215 <row>
26216 <entry><structfield>oldest_xid</structfield></entry>
26217 <entry><type>xid</type></entry>
26218 </row>
26220 <row>
26221 <entry><structfield>oldest_xid_dbid</structfield></entry>
26222 <entry><type>oid</type></entry>
26223 </row>
26225 <row>
26226 <entry><structfield>oldest_active_xid</structfield></entry>
26227 <entry><type>xid</type></entry>
26228 </row>
26230 <row>
26231 <entry><structfield>oldest_multi_xid</structfield></entry>
26232 <entry><type>xid</type></entry>
26233 </row>
26235 <row>
26236 <entry><structfield>oldest_multi_dbid</structfield></entry>
26237 <entry><type>oid</type></entry>
26238 </row>
26240 <row>
26241 <entry><structfield>oldest_commit_ts_xid</structfield></entry>
26242 <entry><type>xid</type></entry>
26243 </row>
26245 <row>
26246 <entry><structfield>newest_commit_ts_xid</structfield></entry>
26247 <entry><type>xid</type></entry>
26248 </row>
26250 <row>
26251 <entry><structfield>checkpoint_time</structfield></entry>
26252 <entry><type>timestamp with time zone</type></entry>
26253 </row>
26255 </tbody>
26256 </tgroup>
26257 </table>
26259 <table id="functions-pg-control-system">
26260 <title><function>pg_control_system</function> Output Columns</title>
26261 <tgroup cols="2">
26262 <thead>
26263 <row>
26264 <entry>Column Name</entry>
26265 <entry>Data Type</entry>
26266 </row>
26267 </thead>
26269 <tbody>
26271 <row>
26272 <entry><structfield>pg_control_version</structfield></entry>
26273 <entry><type>integer</type></entry>
26274 </row>
26276 <row>
26277 <entry><structfield>catalog_version_no</structfield></entry>
26278 <entry><type>integer</type></entry>
26279 </row>
26281 <row>
26282 <entry><structfield>system_identifier</structfield></entry>
26283 <entry><type>bigint</type></entry>
26284 </row>
26286 <row>
26287 <entry><structfield>pg_control_last_modified</structfield></entry>
26288 <entry><type>timestamp with time zone</type></entry>
26289 </row>
26291 </tbody>
26292 </tgroup>
26293 </table>
26295 <table id="functions-pg-control-init">
26296 <title><function>pg_control_init</function> Output Columns</title>
26297 <tgroup cols="2">
26298 <thead>
26299 <row>
26300 <entry>Column Name</entry>
26301 <entry>Data Type</entry>
26302 </row>
26303 </thead>
26305 <tbody>
26307 <row>
26308 <entry><structfield>max_data_alignment</structfield></entry>
26309 <entry><type>integer</type></entry>
26310 </row>
26312 <row>
26313 <entry><structfield>database_block_size</structfield></entry>
26314 <entry><type>integer</type></entry>
26315 </row>
26317 <row>
26318 <entry><structfield>blocks_per_segment</structfield></entry>
26319 <entry><type>integer</type></entry>
26320 </row>
26322 <row>
26323 <entry><structfield>wal_block_size</structfield></entry>
26324 <entry><type>integer</type></entry>
26325 </row>
26327 <row>
26328 <entry><structfield>bytes_per_wal_segment</structfield></entry>
26329 <entry><type>integer</type></entry>
26330 </row>
26332 <row>
26333 <entry><structfield>max_identifier_length</structfield></entry>
26334 <entry><type>integer</type></entry>
26335 </row>
26337 <row>
26338 <entry><structfield>max_index_columns</structfield></entry>
26339 <entry><type>integer</type></entry>
26340 </row>
26342 <row>
26343 <entry><structfield>max_toast_chunk_size</structfield></entry>
26344 <entry><type>integer</type></entry>
26345 </row>
26347 <row>
26348 <entry><structfield>large_object_chunk_size</structfield></entry>
26349 <entry><type>integer</type></entry>
26350 </row>
26352 <row>
26353 <entry><structfield>float8_pass_by_value</structfield></entry>
26354 <entry><type>boolean</type></entry>
26355 </row>
26357 <row>
26358 <entry><structfield>data_page_checksum_version</structfield></entry>
26359 <entry><type>integer</type></entry>
26360 </row>
26362 </tbody>
26363 </tgroup>
26364 </table>
26366 <table id="functions-pg-control-recovery">
26367 <title><function>pg_control_recovery</function> Output Columns</title>
26368 <tgroup cols="2">
26369 <thead>
26370 <row>
26371 <entry>Column Name</entry>
26372 <entry>Data Type</entry>
26373 </row>
26374 </thead>
26376 <tbody>
26378 <row>
26379 <entry><structfield>min_recovery_end_lsn</structfield></entry>
26380 <entry><type>pg_lsn</type></entry>
26381 </row>
26383 <row>
26384 <entry><structfield>min_recovery_end_timeline</structfield></entry>
26385 <entry><type>integer</type></entry>
26386 </row>
26388 <row>
26389 <entry><structfield>backup_start_lsn</structfield></entry>
26390 <entry><type>pg_lsn</type></entry>
26391 </row>
26393 <row>
26394 <entry><structfield>backup_end_lsn</structfield></entry>
26395 <entry><type>pg_lsn</type></entry>
26396 </row>
26398 <row>
26399 <entry><structfield>end_of_backup_record_required</structfield></entry>
26400 <entry><type>boolean</type></entry>
26401 </row>
26403 </tbody>
26404 </tgroup>
26405 </table>
26407 </sect2>
26409 <sect2 id="functions-info-version">
26410 <title>Version Information Functions</title>
26412 <para>
26413 The functions shown in <xref linkend="functions-version"/>
26414 print version information.
26415 </para>
26417 <table id="functions-version">
26418 <title>Version Information Functions</title>
26419 <tgroup cols="1">
26420 <thead>
26421 <row>
26422 <entry role="func_table_entry"><para role="func_signature">
26423 Function
26424 </para>
26425 <para>
26426 Description
26427 </para></entry>
26428 </row>
26429 </thead>
26431 <tbody>
26432 <row>
26433 <entry role="func_table_entry"><para role="func_signature">
26434 <indexterm>
26435 <primary>version</primary>
26436 </indexterm>
26437 <function>version</function> ()
26438 <returnvalue>text</returnvalue>
26439 </para>
26440 <para>
26441 Returns a string describing the <productname>PostgreSQL</productname>
26442 server's version. You can also get this information from
26443 <xref linkend="guc-server-version"/>, or for a machine-readable
26444 version use <xref linkend="guc-server-version-num"/>. Software
26445 developers should use <varname>server_version_num</varname> (available
26446 since 8.2) or <xref linkend="libpq-PQserverVersion"/> instead of
26447 parsing the text version.
26448 </para></entry>
26449 </row>
26451 <row>
26452 <entry role="func_table_entry"><para role="func_signature">
26453 <indexterm>
26454 <primary>unicode_version</primary>
26455 </indexterm>
26456 <function>unicode_version</function> ()
26457 <returnvalue>text</returnvalue>
26458 </para>
26459 <para>
26460 Returns a string representing the version of Unicode used by
26461 <productname>PostgreSQL</productname>.
26462 </para></entry>
26463 </row>
26464 <row>
26465 <entry role="func_table_entry"><para role="func_signature">
26466 <indexterm>
26467 <primary>icu_unicode_version</primary>
26468 </indexterm>
26469 <function>icu_unicode_version</function> ()
26470 <returnvalue>text</returnvalue>
26471 </para>
26472 <para>
26473 Returns a string representing the version of Unicode used by ICU, if
26474 the server was built with ICU support; otherwise returns
26475 <literal>NULL</literal> </para></entry>
26476 </row>
26477 </tbody>
26478 </tgroup>
26479 </table>
26481 </sect2>
26483 </sect1>
26485 <sect1 id="functions-admin">
26486 <title>System Administration Functions</title>
26488 <para>
26489 The functions described in this section are used to control and
26490 monitor a <productname>PostgreSQL</productname> installation.
26491 </para>
26493 <sect2 id="functions-admin-set">
26494 <title>Configuration Settings Functions</title>
26496 <indexterm>
26497 <primary>SET</primary>
26498 </indexterm>
26500 <indexterm>
26501 <primary>SHOW</primary>
26502 </indexterm>
26504 <indexterm>
26505 <primary>configuration</primary>
26506 <secondary sortas="server">of the server</secondary>
26507 <tertiary>functions</tertiary>
26508 </indexterm>
26510 <para>
26511 <xref linkend="functions-admin-set-table"/> shows the functions
26512 available to query and alter run-time configuration parameters.
26513 </para>
26515 <table id="functions-admin-set-table">
26516 <title>Configuration Settings Functions</title>
26517 <tgroup cols="1">
26518 <thead>
26519 <row>
26520 <entry role="func_table_entry"><para role="func_signature">
26521 Function
26522 </para>
26523 <para>
26524 Description
26525 </para>
26526 <para>
26527 Example(s)
26528 </para></entry>
26529 </row>
26530 </thead>
26532 <tbody>
26533 <row>
26534 <entry role="func_table_entry"><para role="func_signature">
26535 <indexterm>
26536 <primary>current_setting</primary>
26537 </indexterm>
26538 <function>current_setting</function> ( <parameter>setting_name</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
26539 <returnvalue>text</returnvalue>
26540 </para>
26541 <para>
26542 Returns the current value of the
26543 setting <parameter>setting_name</parameter>. If there is no such
26544 setting, <function>current_setting</function> throws an error
26545 unless <parameter>missing_ok</parameter> is supplied and
26546 is <literal>true</literal> (in which case NULL is returned).
26547 This function corresponds to
26548 the <acronym>SQL</acronym> command <xref linkend="sql-show"/>.
26549 </para>
26550 <para>
26551 <literal>current_setting('datestyle')</literal>
26552 <returnvalue>ISO, MDY</returnvalue>
26553 </para></entry>
26554 </row>
26556 <row>
26557 <entry role="func_table_entry"><para role="func_signature">
26558 <indexterm>
26559 <primary>set_config</primary>
26560 </indexterm>
26561 <function>set_config</function> (
26562 <parameter>setting_name</parameter> <type>text</type>,
26563 <parameter>new_value</parameter> <type>text</type>,
26564 <parameter>is_local</parameter> <type>boolean</type> )
26565 <returnvalue>text</returnvalue>
26566 </para>
26567 <para>
26568 Sets the parameter <parameter>setting_name</parameter>
26569 to <parameter>new_value</parameter>, and returns that value.
26570 If <parameter>is_local</parameter> is <literal>true</literal>, the new
26571 value will only apply during the current transaction. If you want the
26572 new value to apply for the rest of the current session,
26573 use <literal>false</literal> instead. This function corresponds to
26574 the SQL command <xref linkend="sql-set"/>.
26575 </para>
26576 <para>
26577 <literal>set_config('log_statement_stats', 'off', false)</literal>
26578 <returnvalue>off</returnvalue>
26579 </para></entry>
26580 </row>
26581 </tbody>
26582 </tgroup>
26583 </table>
26585 </sect2>
26587 <sect2 id="functions-admin-signal">
26588 <title>Server Signaling Functions</title>
26590 <indexterm>
26591 <primary>signal</primary>
26592 <secondary sortas="backend">backend processes</secondary>
26593 </indexterm>
26595 <para>
26596 The functions shown in <xref
26597 linkend="functions-admin-signal-table"/> send control signals to
26598 other server processes. Use of these functions is restricted to
26599 superusers by default but access may be granted to others using
26600 <command>GRANT</command>, with noted exceptions.
26601 </para>
26603 <para>
26604 Each of these functions returns <literal>true</literal> if
26605 the signal was successfully sent and <literal>false</literal>
26606 if sending the signal failed.
26607 </para>
26609 <table id="functions-admin-signal-table">
26610 <title>Server Signaling Functions</title>
26611 <tgroup cols="1">
26612 <thead>
26613 <row>
26614 <entry role="func_table_entry"><para role="func_signature">
26615 Function
26616 </para>
26617 <para>
26618 Description
26619 </para></entry>
26620 </row>
26621 </thead>
26623 <tbody>
26624 <row>
26625 <entry role="func_table_entry"><para role="func_signature">
26626 <indexterm>
26627 <primary>pg_cancel_backend</primary>
26628 </indexterm>
26629 <function>pg_cancel_backend</function> ( <parameter>pid</parameter> <type>integer</type> )
26630 <returnvalue>boolean</returnvalue>
26631 </para>
26632 <para>
26633 Cancels the current query of the session whose backend process has the
26634 specified process ID. This is also allowed if the
26635 calling role is a member of the role whose backend is being canceled or
26636 the calling role has privileges of <literal>pg_signal_backend</literal>,
26637 however only superusers can cancel superuser backends.
26638 </para></entry>
26639 </row>
26641 <row>
26642 <entry role="func_table_entry"><para role="func_signature">
26643 <indexterm>
26644 <primary>pg_log_backend_memory_contexts</primary>
26645 </indexterm>
26646 <function>pg_log_backend_memory_contexts</function> ( <parameter>pid</parameter> <type>integer</type> )
26647 <returnvalue>boolean</returnvalue>
26648 </para>
26649 <para>
26650 Requests to log the memory contexts of the backend with the
26651 specified process ID. This function can send the request to
26652 backends and auxiliary processes except logger. These memory contexts
26653 will be logged at
26654 <literal>LOG</literal> message level. They will appear in
26655 the server log based on the log configuration set
26656 (see <xref linkend="runtime-config-logging"/> for more information),
26657 but will not be sent to the client regardless of
26658 <xref linkend="guc-client-min-messages"/>.
26659 </para></entry>
26660 </row>
26662 <row>
26663 <entry role="func_table_entry"><para role="func_signature">
26664 <indexterm>
26665 <primary>pg_reload_conf</primary>
26666 </indexterm>
26667 <function>pg_reload_conf</function> ()
26668 <returnvalue>boolean</returnvalue>
26669 </para>
26670 <para>
26671 Causes all processes of the <productname>PostgreSQL</productname>
26672 server to reload their configuration files. (This is initiated by
26673 sending a <systemitem>SIGHUP</systemitem> signal to the postmaster
26674 process, which in turn sends <systemitem>SIGHUP</systemitem> to each
26675 of its children.) You can use the
26676 <link linkend="view-pg-file-settings"><structname>pg_file_settings</structname></link>,
26677 <link linkend="view-pg-hba-file-rules"><structname>pg_hba_file_rules</structname></link> and
26678 <link linkend="view-pg-hba-file-rules"><structname>pg_ident_file_mappings</structname></link> views
26679 to check the configuration files for possible errors, before reloading.
26680 </para></entry>
26681 </row>
26683 <row>
26684 <entry role="func_table_entry"><para role="func_signature">
26685 <indexterm>
26686 <primary>pg_rotate_logfile</primary>
26687 </indexterm>
26688 <function>pg_rotate_logfile</function> ()
26689 <returnvalue>boolean</returnvalue>
26690 </para>
26691 <para>
26692 Signals the log-file manager to switch to a new output file
26693 immediately. This works only when the built-in log collector is
26694 running, since otherwise there is no log-file manager subprocess.
26695 </para></entry>
26696 </row>
26698 <row>
26699 <entry role="func_table_entry"><para role="func_signature">
26700 <indexterm>
26701 <primary>pg_terminate_backend</primary>
26702 </indexterm>
26703 <function>pg_terminate_backend</function> ( <parameter>pid</parameter> <type>integer</type>, <parameter>timeout</parameter> <type>bigint</type> <literal>DEFAULT</literal> <literal>0</literal> )
26704 <returnvalue>boolean</returnvalue>
26705 </para>
26706 <para>
26707 Terminates the session whose backend process has the
26708 specified process ID. This is also allowed if the calling role
26709 is a member of the role whose backend is being terminated or the
26710 calling role has privileges of <literal>pg_signal_backend</literal>,
26711 however only superusers can terminate superuser backends.
26712 </para>
26713 <para>
26714 If <parameter>timeout</parameter> is not specified or zero, this
26715 function returns <literal>true</literal> whether the process actually
26716 terminates or not, indicating only that the sending of the signal was
26717 successful. If the <parameter>timeout</parameter> is specified (in
26718 milliseconds) and greater than zero, the function waits until the
26719 process is actually terminated or until the given time has passed. If
26720 the process is terminated, the function
26721 returns <literal>true</literal>. On timeout, a warning is emitted and
26722 <literal>false</literal> is returned.
26723 </para></entry>
26724 </row>
26725 </tbody>
26726 </tgroup>
26727 </table>
26729 <para>
26730 <function>pg_cancel_backend</function> and <function>pg_terminate_backend</function>
26731 send signals (<systemitem>SIGINT</systemitem> or <systemitem>SIGTERM</systemitem>
26732 respectively) to backend processes identified by process ID.
26733 The process ID of an active backend can be found from
26734 the <structfield>pid</structfield> column of the
26735 <structname>pg_stat_activity</structname> view, or by listing the
26736 <command>postgres</command> processes on the server (using
26737 <application>ps</application> on Unix or the <application>Task
26738 Manager</application> on <productname>Windows</productname>).
26739 The role of an active backend can be found from the
26740 <structfield>usename</structfield> column of the
26741 <structname>pg_stat_activity</structname> view.
26742 </para>
26744 <para>
26745 <function>pg_log_backend_memory_contexts</function> can be used
26746 to log the memory contexts of a backend process. For example:
26747 <programlisting>
26748 postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid());
26749 pg_log_backend_memory_contexts
26750 --------------------------------
26752 (1 row)
26753 </programlisting>
26754 One message for each memory context will be logged. For example:
26755 <screen>
26756 LOG: logging memory contexts of PID 10377
26757 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid());
26758 LOG: level: 0; TopMemoryContext: 80800 total in 6 blocks; 14432 free (5 chunks); 66368 used
26759 LOG: level: 1; pgstat TabStatusArray lookup hash table: 8192 total in 1 blocks; 1408 free (0 chunks); 6784 used
26760 LOG: level: 1; TopTransactionContext: 8192 total in 1 blocks; 7720 free (1 chunks); 472 used
26761 LOG: level: 1; RowDescriptionContext: 8192 total in 1 blocks; 6880 free (0 chunks); 1312 used
26762 LOG: level: 1; MessageContext: 16384 total in 2 blocks; 5152 free (0 chunks); 11232 used
26763 LOG: level: 1; Operator class cache: 8192 total in 1 blocks; 512 free (0 chunks); 7680 used
26764 LOG: level: 1; smgr relation table: 16384 total in 2 blocks; 4544 free (3 chunks); 11840 used
26765 LOG: level: 1; TransactionAbortContext: 32768 total in 1 blocks; 32504 free (0 chunks); 264 used
26767 LOG: level: 1; ErrorContext: 8192 total in 1 blocks; 7928 free (3 chunks); 264 used
26768 LOG: Grand total: 1651920 bytes in 201 blocks; 622360 free (88 chunks); 1029560 used
26769 </screen>
26770 If there are more than 100 child contexts under the same parent, the first
26771 100 child contexts are logged, along with a summary of the remaining contexts.
26772 Note that frequent calls to this function could incur significant overhead,
26773 because it may generate a large number of log messages.
26774 </para>
26776 </sect2>
26778 <sect2 id="functions-admin-backup">
26779 <title>Backup Control Functions</title>
26781 <indexterm>
26782 <primary>backup</primary>
26783 </indexterm>
26785 <para>
26786 The functions shown in <xref
26787 linkend="functions-admin-backup-table"/> assist in making on-line backups.
26788 These functions cannot be executed during recovery (except
26789 <function>pg_backup_start</function>,
26790 <function>pg_backup_stop</function>,
26791 and <function>pg_wal_lsn_diff</function>).
26792 </para>
26794 <para>
26795 For details about proper usage of these functions, see
26796 <xref linkend="continuous-archiving"/>.
26797 </para>
26799 <table id="functions-admin-backup-table">
26800 <title>Backup Control Functions</title>
26801 <tgroup cols="1">
26802 <thead>
26803 <row>
26804 <entry role="func_table_entry"><para role="func_signature">
26805 Function
26806 </para>
26807 <para>
26808 Description
26809 </para></entry>
26810 </row>
26811 </thead>
26813 <tbody>
26814 <row>
26815 <entry role="func_table_entry"><para role="func_signature">
26816 <indexterm>
26817 <primary>pg_create_restore_point</primary>
26818 </indexterm>
26819 <function>pg_create_restore_point</function> ( <parameter>name</parameter> <type>text</type> )
26820 <returnvalue>pg_lsn</returnvalue>
26821 </para>
26822 <para>
26823 Creates a named marker record in the write-ahead log that can later be
26824 used as a recovery target, and returns the corresponding write-ahead
26825 log location. The given name can then be used with
26826 <xref linkend="guc-recovery-target-name"/> to specify the point up to
26827 which recovery will proceed. Avoid creating multiple restore points
26828 with the same name, since recovery will stop at the first one whose
26829 name matches the recovery target.
26830 </para>
26831 <para>
26832 This function is restricted to superusers by default, but other users
26833 can be granted EXECUTE to run the function.
26834 </para></entry>
26835 </row>
26837 <row>
26838 <entry role="func_table_entry"><para role="func_signature">
26839 <indexterm>
26840 <primary>pg_current_wal_flush_lsn</primary>
26841 </indexterm>
26842 <function>pg_current_wal_flush_lsn</function> ()
26843 <returnvalue>pg_lsn</returnvalue>
26844 </para>
26845 <para>
26846 Returns the current write-ahead log flush location (see notes below).
26847 </para></entry>
26848 </row>
26850 <row>
26851 <entry role="func_table_entry"><para role="func_signature">
26852 <indexterm>
26853 <primary>pg_current_wal_insert_lsn</primary>
26854 </indexterm>
26855 <function>pg_current_wal_insert_lsn</function> ()
26856 <returnvalue>pg_lsn</returnvalue>
26857 </para>
26858 <para>
26859 Returns the current write-ahead log insert location (see notes below).
26860 </para></entry>
26861 </row>
26863 <row>
26864 <entry role="func_table_entry"><para role="func_signature">
26865 <indexterm>
26866 <primary>pg_current_wal_lsn</primary>
26867 </indexterm>
26868 <function>pg_current_wal_lsn</function> ()
26869 <returnvalue>pg_lsn</returnvalue>
26870 </para>
26871 <para>
26872 Returns the current write-ahead log write location (see notes below).
26873 </para></entry>
26874 </row>
26876 <row>
26877 <entry role="func_table_entry"><para role="func_signature">
26878 <indexterm>
26879 <primary>pg_backup_start</primary>
26880 </indexterm>
26881 <function>pg_backup_start</function> (
26882 <parameter>label</parameter> <type>text</type>
26883 <optional>, <parameter>fast</parameter> <type>boolean</type>
26884 </optional> )
26885 <returnvalue>pg_lsn</returnvalue>
26886 </para>
26887 <para>
26888 Prepares the server to begin an on-line backup. The only required
26889 parameter is an arbitrary user-defined label for the backup.
26890 (Typically this would be the name under which the backup dump file
26891 will be stored.)
26892 If the optional second parameter is given as <literal>true</literal>,
26893 it specifies executing <function>pg_backup_start</function> as quickly
26894 as possible. This forces an immediate checkpoint which will cause a
26895 spike in I/O operations, slowing any concurrently executing queries.
26896 </para>
26897 <para>
26898 This function is restricted to superusers by default, but other users
26899 can be granted EXECUTE to run the function.
26900 </para></entry>
26901 </row>
26903 <row>
26904 <entry role="func_table_entry"><para role="func_signature">
26905 <indexterm>
26906 <primary>pg_backup_stop</primary>
26907 </indexterm>
26908 <function>pg_backup_stop</function> (
26909 <optional><parameter>wait_for_archive</parameter> <type>boolean</type>
26910 </optional> )
26911 <returnvalue>record</returnvalue>
26912 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
26913 <parameter>labelfile</parameter> <type>text</type>,
26914 <parameter>spcmapfile</parameter> <type>text</type> )
26915 </para>
26916 <para>
26917 Finishes performing an on-line backup. The desired contents of the
26918 backup label file and the tablespace map file are returned as part of
26919 the result of the function and must be written to files in the
26920 backup area. These files must not be written to the live data directory
26921 (doing so will cause PostgreSQL to fail to restart in the event of a
26922 crash).
26923 </para>
26924 <para>
26925 There is an optional parameter of type <type>boolean</type>.
26926 If false, the function will return immediately after the backup is
26927 completed, without waiting for WAL to be archived. This behavior is
26928 only useful with backup software that independently monitors WAL
26929 archiving. Otherwise, WAL required to make the backup consistent might
26930 be missing and make the backup useless. By default or when this
26931 parameter is true, <function>pg_backup_stop</function> will wait for
26932 WAL to be archived when archiving is enabled. (On a standby, this
26933 means that it will wait only when <varname>archive_mode</varname> =
26934 <literal>always</literal>. If write activity on the primary is low,
26935 it may be useful to run <function>pg_switch_wal</function> on the
26936 primary in order to trigger an immediate segment switch.)
26937 </para>
26938 <para>
26939 When executed on a primary, this function also creates a backup
26940 history file in the write-ahead log archive area. The history file
26941 includes the label given to <function>pg_backup_start</function>, the
26942 starting and ending write-ahead log locations for the backup, and the
26943 starting and ending times of the backup. After recording the ending
26944 location, the current write-ahead log insertion point is automatically
26945 advanced to the next write-ahead log file, so that the ending
26946 write-ahead log file can be archived immediately to complete the
26947 backup.
26948 </para>
26949 <para>
26950 The result of the function is a single record.
26951 The <parameter>lsn</parameter> column holds the backup's ending
26952 write-ahead log location (which again can be ignored). The second
26953 column returns the contents of the backup label file, and the third
26954 column returns the contents of the tablespace map file. These must be
26955 stored as part of the backup and are required as part of the restore
26956 process.
26957 </para>
26958 <para>
26959 This function is restricted to superusers by default, but other users
26960 can be granted EXECUTE to run the function.
26961 </para></entry>
26962 </row>
26964 <row>
26965 <entry role="func_table_entry"><para role="func_signature">
26966 <indexterm>
26967 <primary>pg_switch_wal</primary>
26968 </indexterm>
26969 <function>pg_switch_wal</function> ()
26970 <returnvalue>pg_lsn</returnvalue>
26971 </para>
26972 <para>
26973 Forces the server to switch to a new write-ahead log file, which
26974 allows the current file to be archived (assuming you are using
26975 continuous archiving). The result is the ending write-ahead log
26976 location plus 1 within the just-completed write-ahead log file. If
26977 there has been no write-ahead log activity since the last write-ahead
26978 log switch, <function>pg_switch_wal</function> does nothing and
26979 returns the start location of the write-ahead log file currently in
26980 use.
26981 </para>
26982 <para>
26983 This function is restricted to superusers by default, but other users
26984 can be granted EXECUTE to run the function.
26985 </para></entry>
26986 </row>
26988 <row>
26989 <entry role="func_table_entry"><para role="func_signature">
26990 <indexterm>
26991 <primary>pg_walfile_name</primary>
26992 </indexterm>
26993 <function>pg_walfile_name</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
26994 <returnvalue>text</returnvalue>
26995 </para>
26996 <para>
26997 Converts a write-ahead log location to the name of the WAL file
26998 holding that location.
26999 </para></entry>
27000 </row>
27002 <row>
27003 <entry role="func_table_entry"><para role="func_signature">
27004 <indexterm>
27005 <primary>pg_walfile_name_offset</primary>
27006 </indexterm>
27007 <function>pg_walfile_name_offset</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
27008 <returnvalue>record</returnvalue>
27009 ( <parameter>file_name</parameter> <type>text</type>,
27010 <parameter>file_offset</parameter> <type>integer</type> )
27011 </para>
27012 <para>
27013 Converts a write-ahead log location to a WAL file name and byte offset
27014 within that file.
27015 </para></entry>
27016 </row>
27018 <row>
27019 <entry role="func_table_entry"><para role="func_signature">
27020 <indexterm>
27021 <primary>pg_split_walfile_name</primary>
27022 </indexterm>
27023 <function>pg_split_walfile_name</function> ( <parameter>file_name</parameter> <type>text</type> )
27024 <returnvalue>record</returnvalue>
27025 ( <parameter>segment_number</parameter> <type>numeric</type>,
27026 <parameter>timeline_id</parameter> <type>bigint</type> )
27027 </para>
27028 <para>
27029 Extracts the sequence number and timeline ID from a WAL file
27030 name.
27031 </para></entry>
27032 </row>
27034 <row>
27035 <entry role="func_table_entry"><para role="func_signature">
27036 <indexterm>
27037 <primary>pg_wal_lsn_diff</primary>
27038 </indexterm>
27039 <function>pg_wal_lsn_diff</function> ( <parameter>lsn1</parameter> <type>pg_lsn</type>, <parameter>lsn2</parameter> <type>pg_lsn</type> )
27040 <returnvalue>numeric</returnvalue>
27041 </para>
27042 <para>
27043 Calculates the difference in bytes (<parameter>lsn1</parameter> - <parameter>lsn2</parameter>) between two write-ahead log
27044 locations. This can be used
27045 with <structname>pg_stat_replication</structname> or some of the
27046 functions shown in <xref linkend="functions-admin-backup-table"/> to
27047 get the replication lag.
27048 </para></entry>
27049 </row>
27050 </tbody>
27051 </tgroup>
27052 </table>
27054 <para>
27055 <function>pg_current_wal_lsn</function> displays the current write-ahead
27056 log write location in the same format used by the above functions.
27057 Similarly, <function>pg_current_wal_insert_lsn</function> displays the
27058 current write-ahead log insertion location
27059 and <function>pg_current_wal_flush_lsn</function> displays the current
27060 write-ahead log flush location. The insertion location is
27061 the <quote>logical</quote> end of the write-ahead log at any instant,
27062 while the write location is the end of what has actually been written out
27063 from the server's internal buffers, and the flush location is the last
27064 location known to be written to durable storage. The write location is the
27065 end of what can be examined from outside the server, and is usually what
27066 you want if you are interested in archiving partially-complete write-ahead
27067 log files. The insertion and flush locations are made available primarily
27068 for server debugging purposes. These are all read-only operations and do
27069 not require superuser permissions.
27070 </para>
27072 <para>
27073 You can use <function>pg_walfile_name_offset</function> to extract the
27074 corresponding write-ahead log file name and byte offset from
27075 a <type>pg_lsn</type> value. For example:
27076 <programlisting>
27077 postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn);
27078 file_name | file_offset
27079 --------------------------+-------------
27080 00000001000000000000000D | 4039624
27081 (1 row)
27082 </programlisting>
27083 Similarly, <function>pg_walfile_name</function> extracts just the write-ahead log file name.
27084 </para>
27086 <para>
27087 <function>pg_split_walfile_name</function> is useful to compute a
27088 <acronym>LSN</acronym> from a file offset and WAL file name, for example:
27089 <programlisting>
27090 postgres=# \set file_name '000000010000000100C000AB'
27091 postgres=# \set offset 256
27092 postgres=# SELECT '0/0'::pg_lsn + pd.segment_number * ps.setting::int + :offset AS lsn
27093 FROM pg_split_walfile_name(:'file_name') pd,
27094 pg_show_all_settings() ps
27095 WHERE ps.name = 'wal_segment_size';
27097 ---------------
27098 C001/AB000100
27099 (1 row)
27100 </programlisting>
27101 </para>
27103 </sect2>
27105 <sect2 id="functions-recovery-control">
27106 <title>Recovery Control Functions</title>
27108 <para>
27109 The functions shown in <xref
27110 linkend="functions-recovery-info-table"/> provide information
27111 about the current status of a standby server.
27112 These functions may be executed both during recovery and in normal running.
27113 </para>
27115 <table id="functions-recovery-info-table">
27116 <title>Recovery Information Functions</title>
27117 <tgroup cols="1">
27118 <thead>
27119 <row>
27120 <entry role="func_table_entry"><para role="func_signature">
27121 Function
27122 </para>
27123 <para>
27124 Description
27125 </para></entry>
27126 </row>
27127 </thead>
27129 <tbody>
27130 <row>
27131 <entry role="func_table_entry"><para role="func_signature">
27132 <indexterm>
27133 <primary>pg_is_in_recovery</primary>
27134 </indexterm>
27135 <function>pg_is_in_recovery</function> ()
27136 <returnvalue>boolean</returnvalue>
27137 </para>
27138 <para>
27139 Returns true if recovery is still in progress.
27140 </para></entry>
27141 </row>
27143 <row>
27144 <entry role="func_table_entry"><para role="func_signature">
27145 <indexterm>
27146 <primary>pg_last_wal_receive_lsn</primary>
27147 </indexterm>
27148 <function>pg_last_wal_receive_lsn</function> ()
27149 <returnvalue>pg_lsn</returnvalue>
27150 </para>
27151 <para>
27152 Returns the last write-ahead log location that has been received and
27153 synced to disk by streaming replication. While streaming replication
27154 is in progress this will increase monotonically. If recovery has
27155 completed then this will remain static at the location of the last WAL
27156 record received and synced to disk during recovery. If streaming
27157 replication is disabled, or if it has not yet started, the function
27158 returns <literal>NULL</literal>.
27159 </para></entry>
27160 </row>
27162 <row>
27163 <entry role="func_table_entry"><para role="func_signature">
27164 <indexterm>
27165 <primary>pg_last_wal_replay_lsn</primary>
27166 </indexterm>
27167 <function>pg_last_wal_replay_lsn</function> ()
27168 <returnvalue>pg_lsn</returnvalue>
27169 </para>
27170 <para>
27171 Returns the last write-ahead log location that has been replayed
27172 during recovery. If recovery is still in progress this will increase
27173 monotonically. If recovery has completed then this will remain
27174 static at the location of the last WAL record applied during recovery.
27175 When the server has been started normally without recovery, the
27176 function returns <literal>NULL</literal>.
27177 </para></entry>
27178 </row>
27180 <row>
27181 <entry role="func_table_entry"><para role="func_signature">
27182 <indexterm>
27183 <primary>pg_last_xact_replay_timestamp</primary>
27184 </indexterm>
27185 <function>pg_last_xact_replay_timestamp</function> ()
27186 <returnvalue>timestamp with time zone</returnvalue>
27187 </para>
27188 <para>
27189 Returns the time stamp of the last transaction replayed during
27190 recovery. This is the time at which the commit or abort WAL record
27191 for that transaction was generated on the primary. If no transactions
27192 have been replayed during recovery, the function
27193 returns <literal>NULL</literal>. Otherwise, if recovery is still in
27194 progress this will increase monotonically. If recovery has completed
27195 then this will remain static at the time of the last transaction
27196 applied during recovery. When the server has been started normally
27197 without recovery, the function returns <literal>NULL</literal>.
27198 </para></entry>
27199 </row>
27201 <row>
27202 <entry role="func_table_entry"><para role="func_signature">
27203 <indexterm>
27204 <primary>pg_get_wal_resource_managers</primary>
27205 </indexterm>
27206 <function>pg_get_wal_resource_managers</function> ()
27207 <returnvalue>setof record</returnvalue>
27208 ( <parameter>rm_id</parameter> <type>integer</type>,
27209 <parameter>rm_name</parameter> <type>text</type>,
27210 <parameter>rm_builtin</parameter> <type>boolean</type> )
27211 </para>
27212 <para>
27213 Returns the currently-loaded WAL resource managers in the system. The
27214 column <parameter>rm_builtin</parameter> indicates whether it's a
27215 built-in resource manager, or a custom resource manager loaded by an
27216 extension.
27217 </para></entry>
27218 </row>
27219 </tbody>
27220 </tgroup>
27221 </table>
27223 <para>
27224 The functions shown in <xref
27225 linkend="functions-recovery-control-table"/> control the progress of recovery.
27226 These functions may be executed only during recovery.
27227 </para>
27229 <table id="functions-recovery-control-table">
27230 <title>Recovery Control Functions</title>
27231 <tgroup cols="1">
27232 <thead>
27233 <row>
27234 <entry role="func_table_entry"><para role="func_signature">
27235 Function
27236 </para>
27237 <para>
27238 Description
27239 </para></entry>
27240 </row>
27241 </thead>
27243 <tbody>
27244 <row>
27245 <entry role="func_table_entry"><para role="func_signature">
27246 <indexterm>
27247 <primary>pg_is_wal_replay_paused</primary>
27248 </indexterm>
27249 <function>pg_is_wal_replay_paused</function> ()
27250 <returnvalue>boolean</returnvalue>
27251 </para>
27252 <para>
27253 Returns true if recovery pause is requested.
27254 </para></entry>
27255 </row>
27257 <row>
27258 <entry role="func_table_entry"><para role="func_signature">
27259 <indexterm>
27260 <primary>pg_get_wal_replay_pause_state</primary>
27261 </indexterm>
27262 <function>pg_get_wal_replay_pause_state</function> ()
27263 <returnvalue>text</returnvalue>
27264 </para>
27265 <para>
27266 Returns recovery pause state. The return values are <literal>
27267 not paused</literal> if pause is not requested, <literal>
27268 pause requested</literal> if pause is requested but recovery is
27269 not yet paused, and <literal>paused</literal> if the recovery is
27270 actually paused.
27271 </para></entry>
27272 </row>
27274 <row>
27275 <entry role="func_table_entry"><para role="func_signature">
27276 <indexterm>
27277 <primary>pg_promote</primary>
27278 </indexterm>
27279 <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> )
27280 <returnvalue>boolean</returnvalue>
27281 </para>
27282 <para>
27283 Promotes a standby server to primary status.
27284 With <parameter>wait</parameter> set to <literal>true</literal> (the
27285 default), the function waits until promotion is completed
27286 or <parameter>wait_seconds</parameter> seconds have passed, and
27287 returns <literal>true</literal> if promotion is successful
27288 and <literal>false</literal> otherwise.
27289 If <parameter>wait</parameter> is set to <literal>false</literal>, the
27290 function returns <literal>true</literal> immediately after sending a
27291 <literal>SIGUSR1</literal> signal to the postmaster to trigger
27292 promotion.
27293 </para>
27294 <para>
27295 This function is restricted to superusers by default, but other users
27296 can be granted EXECUTE to run the function.
27297 </para></entry>
27298 </row>
27300 <row>
27301 <entry role="func_table_entry"><para role="func_signature">
27302 <indexterm>
27303 <primary>pg_wal_replay_pause</primary>
27304 </indexterm>
27305 <function>pg_wal_replay_pause</function> ()
27306 <returnvalue>void</returnvalue>
27307 </para>
27308 <para>
27309 Request to pause recovery. A request doesn't mean that recovery stops
27310 right away. If you want a guarantee that recovery is actually paused,
27311 you need to check for the recovery pause state returned by
27312 <function>pg_get_wal_replay_pause_state()</function>. Note that
27313 <function>pg_is_wal_replay_paused()</function> returns whether a request
27314 is made. While recovery is paused, no further database changes are applied.
27315 If hot standby is active, all new queries will see the same consistent
27316 snapshot of the database, and no further query conflicts will be generated
27317 until recovery is resumed.
27318 </para>
27319 <para>
27320 This function is restricted to superusers by default, but other users
27321 can be granted EXECUTE to run the function.
27322 </para></entry>
27323 </row>
27325 <row>
27326 <entry role="func_table_entry"><para role="func_signature">
27327 <indexterm>
27328 <primary>pg_wal_replay_resume</primary>
27329 </indexterm>
27330 <function>pg_wal_replay_resume</function> ()
27331 <returnvalue>void</returnvalue>
27332 </para>
27333 <para>
27334 Restarts recovery if it was paused.
27335 </para>
27336 <para>
27337 This function is restricted to superusers by default, but other users
27338 can be granted EXECUTE to run the function.
27339 </para></entry>
27340 </row>
27341 </tbody>
27342 </tgroup>
27343 </table>
27345 <para>
27346 <function>pg_wal_replay_pause</function> and
27347 <function>pg_wal_replay_resume</function> cannot be executed while
27348 a promotion is ongoing. If a promotion is triggered while recovery
27349 is paused, the paused state ends and promotion continues.
27350 </para>
27352 <para>
27353 If streaming replication is disabled, the paused state may continue
27354 indefinitely without a problem. If streaming replication is in
27355 progress then WAL records will continue to be received, which will
27356 eventually fill available disk space, depending upon the duration of
27357 the pause, the rate of WAL generation and available disk space.
27358 </para>
27360 </sect2>
27362 <sect2 id="functions-snapshot-synchronization">
27363 <title>Snapshot Synchronization Functions</title>
27365 <para>
27366 <productname>PostgreSQL</productname> allows database sessions to synchronize their
27367 snapshots. A <firstterm>snapshot</firstterm> determines which data is visible to the
27368 transaction that is using the snapshot. Synchronized snapshots are
27369 necessary when two or more sessions need to see identical content in the
27370 database. If two sessions just start their transactions independently,
27371 there is always a possibility that some third transaction commits
27372 between the executions of the two <command>START TRANSACTION</command> commands,
27373 so that one session sees the effects of that transaction and the other
27374 does not.
27375 </para>
27377 <para>
27378 To solve this problem, <productname>PostgreSQL</productname> allows a transaction to
27379 <firstterm>export</firstterm> the snapshot it is using. As long as the exporting
27380 transaction remains open, other transactions can <firstterm>import</firstterm> its
27381 snapshot, and thereby be guaranteed that they see exactly the same view
27382 of the database that the first transaction sees. But note that any
27383 database changes made by any one of these transactions remain invisible
27384 to the other transactions, as is usual for changes made by uncommitted
27385 transactions. So the transactions are synchronized with respect to
27386 pre-existing data, but act normally for changes they make themselves.
27387 </para>
27389 <para>
27390 Snapshots are exported with the <function>pg_export_snapshot</function> function,
27391 shown in <xref linkend="functions-snapshot-synchronization-table"/>, and
27392 imported with the <xref linkend="sql-set-transaction"/> command.
27393 </para>
27395 <table id="functions-snapshot-synchronization-table">
27396 <title>Snapshot Synchronization Functions</title>
27397 <tgroup cols="1">
27398 <thead>
27399 <row>
27400 <entry role="func_table_entry"><para role="func_signature">
27401 Function
27402 </para>
27403 <para>
27404 Description
27405 </para></entry>
27406 </row>
27407 </thead>
27409 <tbody>
27410 <row>
27411 <entry role="func_table_entry"><para role="func_signature">
27412 <indexterm>
27413 <primary>pg_export_snapshot</primary>
27414 </indexterm>
27415 <function>pg_export_snapshot</function> ()
27416 <returnvalue>text</returnvalue>
27417 </para>
27418 <para>
27419 Saves the transaction's current snapshot and returns
27420 a <type>text</type> string identifying the snapshot. This string must
27421 be passed (outside the database) to clients that want to import the
27422 snapshot. The snapshot is available for import only until the end of
27423 the transaction that exported it.
27424 </para>
27425 <para>
27426 A transaction can export more than one snapshot, if needed. Note that
27427 doing so is only useful in <literal>READ COMMITTED</literal>
27428 transactions, since in <literal>REPEATABLE READ</literal> and higher
27429 isolation levels, transactions use the same snapshot throughout their
27430 lifetime. Once a transaction has exported any snapshots, it cannot be
27431 prepared with <xref linkend="sql-prepare-transaction"/>.
27432 </para></entry>
27433 </row>
27434 <row>
27435 <entry role="func_table_entry"><para role="func_signature">
27436 <indexterm>
27437 <primary>pg_log_standby_snapshot</primary>
27438 </indexterm>
27439 <function>pg_log_standby_snapshot</function> ()
27440 <returnvalue>pg_lsn</returnvalue>
27441 </para>
27442 <para>
27443 Take a snapshot of running transactions and write it to WAL, without
27444 having to wait for bgwriter or checkpointer to log one. This is useful
27445 for logical decoding on standby, as logical slot creation has to wait
27446 until such a record is replayed on the standby.
27447 </para></entry>
27448 </row>
27449 </tbody>
27450 </tgroup>
27451 </table>
27453 </sect2>
27455 <sect2 id="functions-replication">
27456 <title>Replication Management Functions</title>
27458 <para>
27459 The functions shown
27460 in <xref linkend="functions-replication-table"/> are for
27461 controlling and interacting with replication features.
27462 See <xref linkend="streaming-replication"/>,
27463 <xref linkend="streaming-replication-slots"/>, and
27464 <xref linkend="replication-origins"/>
27465 for information about the underlying features.
27466 Use of functions for replication origin is only allowed to the
27467 superuser by default, but may be allowed to other users by using the
27468 <literal>GRANT</literal> command.
27469 Use of functions for replication slots is restricted to superusers
27470 and users having <literal>REPLICATION</literal> privilege.
27471 </para>
27473 <para>
27474 Many of these functions have equivalent commands in the replication
27475 protocol; see <xref linkend="protocol-replication"/>.
27476 </para>
27478 <para>
27479 The functions described in
27480 <xref linkend="functions-admin-backup"/>,
27481 <xref linkend="functions-recovery-control"/>, and
27482 <xref linkend="functions-snapshot-synchronization"/>
27483 are also relevant for replication.
27484 </para>
27486 <table id="functions-replication-table">
27487 <title>Replication Management Functions</title>
27488 <tgroup cols="1">
27489 <thead>
27490 <row>
27491 <entry role="func_table_entry"><para role="func_signature">
27492 Function
27493 </para>
27494 <para>
27495 Description
27496 </para></entry>
27497 </row>
27498 </thead>
27500 <tbody>
27501 <row>
27502 <entry role="func_table_entry"><para role="func_signature">
27503 <indexterm>
27504 <primary>pg_create_physical_replication_slot</primary>
27505 </indexterm>
27506 <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> )
27507 <returnvalue>record</returnvalue>
27508 ( <parameter>slot_name</parameter> <type>name</type>,
27509 <parameter>lsn</parameter> <type>pg_lsn</type> )
27510 </para>
27511 <para>
27512 Creates a new physical replication slot named
27513 <parameter>slot_name</parameter>. The optional second parameter,
27514 when <literal>true</literal>, specifies that the <acronym>LSN</acronym> for this
27515 replication slot be reserved immediately; otherwise
27516 the <acronym>LSN</acronym> is reserved on first connection from a streaming
27517 replication client. Streaming changes from a physical slot is only
27518 possible with the streaming-replication protocol &mdash;
27519 see <xref linkend="protocol-replication"/>. The optional third
27520 parameter, <parameter>temporary</parameter>, when set to true, specifies that
27521 the slot should not be permanently stored to disk and is only meant
27522 for use by the current session. Temporary slots are also
27523 released upon any error. This function corresponds
27524 to the replication protocol command <literal>CREATE_REPLICATION_SLOT
27525 ... PHYSICAL</literal>.
27526 </para></entry>
27527 </row>
27529 <row>
27530 <entry role="func_table_entry"><para role="func_signature">
27531 <indexterm>
27532 <primary>pg_drop_replication_slot</primary>
27533 </indexterm>
27534 <function>pg_drop_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type> )
27535 <returnvalue>void</returnvalue>
27536 </para>
27537 <para>
27538 Drops the physical or logical replication slot
27539 named <parameter>slot_name</parameter>. Same as replication protocol
27540 command <literal>DROP_REPLICATION_SLOT</literal>. For logical slots, this must
27541 be called while connected to the same database the slot was created on.
27542 </para></entry>
27543 </row>
27545 <row>
27546 <entry role="func_table_entry"><para role="func_signature">
27547 <indexterm>
27548 <primary>pg_create_logical_replication_slot</primary>
27549 </indexterm>
27550 <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> )
27551 <returnvalue>record</returnvalue>
27552 ( <parameter>slot_name</parameter> <type>name</type>,
27553 <parameter>lsn</parameter> <type>pg_lsn</type> )
27554 </para>
27555 <para>
27556 Creates a new logical (decoding) replication slot named
27557 <parameter>slot_name</parameter> using the output plugin
27558 <parameter>plugin</parameter>. The optional third
27559 parameter, <parameter>temporary</parameter>, when set to true, specifies that
27560 the slot should not be permanently stored to disk and is only meant
27561 for use by the current session. Temporary slots are also
27562 released upon any error. The optional fourth parameter,
27563 <parameter>twophase</parameter>, when set to true, specifies
27564 that the decoding of prepared transactions is enabled for this
27565 slot. A call to this function has the same effect as the replication
27566 protocol command <literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>.
27567 </para></entry>
27568 </row>
27570 <row>
27571 <entry role="func_table_entry"><para role="func_signature">
27572 <indexterm>
27573 <primary>pg_copy_physical_replication_slot</primary>
27574 </indexterm>
27575 <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> )
27576 <returnvalue>record</returnvalue>
27577 ( <parameter>slot_name</parameter> <type>name</type>,
27578 <parameter>lsn</parameter> <type>pg_lsn</type> )
27579 </para>
27580 <para>
27581 Copies an existing physical replication slot named <parameter>src_slot_name</parameter>
27582 to a physical replication slot named <parameter>dst_slot_name</parameter>.
27583 The copied physical slot starts to reserve WAL from the same <acronym>LSN</acronym> as the
27584 source slot.
27585 <parameter>temporary</parameter> is optional. If <parameter>temporary</parameter>
27586 is omitted, the same value as the source slot is used.
27587 </para></entry>
27588 </row>
27590 <row>
27591 <entry role="func_table_entry"><para role="func_signature">
27592 <indexterm>
27593 <primary>pg_copy_logical_replication_slot</primary>
27594 </indexterm>
27595 <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> )
27596 <returnvalue>record</returnvalue>
27597 ( <parameter>slot_name</parameter> <type>name</type>,
27598 <parameter>lsn</parameter> <type>pg_lsn</type> )
27599 </para>
27600 <para>
27601 Copies an existing logical replication slot
27602 named <parameter>src_slot_name</parameter> to a logical replication
27603 slot named <parameter>dst_slot_name</parameter>, optionally changing
27604 the output plugin and persistence. The copied logical slot starts
27605 from the same <acronym>LSN</acronym> as the source logical slot. Both
27606 <parameter>temporary</parameter> and <parameter>plugin</parameter> are
27607 optional; if they are omitted, the values of the source slot are used.
27608 </para></entry>
27609 </row>
27611 <row>
27612 <entry role="func_table_entry"><para role="func_signature">
27613 <indexterm>
27614 <primary>pg_logical_slot_get_changes</primary>
27615 </indexterm>
27616 <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> )
27617 <returnvalue>setof record</returnvalue>
27618 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27619 <parameter>xid</parameter> <type>xid</type>,
27620 <parameter>data</parameter> <type>text</type> )
27621 </para>
27622 <para>
27623 Returns changes in the slot <parameter>slot_name</parameter>, starting
27624 from the point from which changes have been consumed last. If
27625 <parameter>upto_lsn</parameter>
27626 and <parameter>upto_nchanges</parameter> are NULL,
27627 logical decoding will continue until end of WAL. If
27628 <parameter>upto_lsn</parameter> is non-NULL, decoding will include only
27629 those transactions which commit prior to the specified LSN. If
27630 <parameter>upto_nchanges</parameter> is non-NULL, decoding will
27631 stop when the number of rows produced by decoding exceeds
27632 the specified value. Note, however, that the actual number of
27633 rows returned may be larger, since this limit is only checked after
27634 adding the rows produced when decoding each new transaction commit.
27635 </para></entry>
27636 </row>
27638 <row>
27639 <entry role="func_table_entry"><para role="func_signature">
27640 <indexterm>
27641 <primary>pg_logical_slot_peek_changes</primary>
27642 </indexterm>
27643 <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> )
27644 <returnvalue>setof record</returnvalue>
27645 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27646 <parameter>xid</parameter> <type>xid</type>,
27647 <parameter>data</parameter> <type>text</type> )
27648 </para>
27649 <para>
27650 Behaves just like
27651 the <function>pg_logical_slot_get_changes()</function> function,
27652 except that changes are not consumed; that is, they will be returned
27653 again on future calls.
27654 </para></entry>
27655 </row>
27657 <row>
27658 <entry role="func_table_entry"><para role="func_signature">
27659 <indexterm>
27660 <primary>pg_logical_slot_get_binary_changes</primary>
27661 </indexterm>
27662 <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> )
27663 <returnvalue>setof record</returnvalue>
27664 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27665 <parameter>xid</parameter> <type>xid</type>,
27666 <parameter>data</parameter> <type>bytea</type> )
27667 </para>
27668 <para>
27669 Behaves just like
27670 the <function>pg_logical_slot_get_changes()</function> function,
27671 except that changes are returned as <type>bytea</type>.
27672 </para></entry>
27673 </row>
27675 <row>
27676 <entry role="func_table_entry"><para role="func_signature">
27677 <indexterm>
27678 <primary>pg_logical_slot_peek_binary_changes</primary>
27679 </indexterm>
27680 <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> )
27681 <returnvalue>setof record</returnvalue>
27682 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27683 <parameter>xid</parameter> <type>xid</type>,
27684 <parameter>data</parameter> <type>bytea</type> )
27685 </para>
27686 <para>
27687 Behaves just like
27688 the <function>pg_logical_slot_peek_changes()</function> function,
27689 except that changes are returned as <type>bytea</type>.
27690 </para></entry>
27691 </row>
27693 <row>
27694 <entry role="func_table_entry"><para role="func_signature">
27695 <indexterm>
27696 <primary>pg_replication_slot_advance</primary>
27697 </indexterm>
27698 <function>pg_replication_slot_advance</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type> )
27699 <returnvalue>record</returnvalue>
27700 ( <parameter>slot_name</parameter> <type>name</type>,
27701 <parameter>end_lsn</parameter> <type>pg_lsn</type> )
27702 </para>
27703 <para>
27704 Advances the current confirmed position of a replication slot named
27705 <parameter>slot_name</parameter>. The slot will not be moved backwards,
27706 and it will not be moved beyond the current insert location. Returns
27707 the name of the slot and the actual position that it was advanced to.
27708 The updated slot position information is written out at the next
27709 checkpoint if any advancing is done. So in the event of a crash, the
27710 slot may return to an earlier position.
27711 </para></entry>
27712 </row>
27714 <row>
27715 <entry id="pg-replication-origin-create" role="func_table_entry"><para role="func_signature">
27716 <indexterm>
27717 <primary>pg_replication_origin_create</primary>
27718 </indexterm>
27719 <function>pg_replication_origin_create</function> ( <parameter>node_name</parameter> <type>text</type> )
27720 <returnvalue>oid</returnvalue>
27721 </para>
27722 <para>
27723 Creates a replication origin with the given external
27724 name, and returns the internal ID assigned to it.
27725 </para></entry>
27726 </row>
27728 <row>
27729 <entry id="pg-replication-origin-drop" role="func_table_entry"><para role="func_signature">
27730 <indexterm>
27731 <primary>pg_replication_origin_drop</primary>
27732 </indexterm>
27733 <function>pg_replication_origin_drop</function> ( <parameter>node_name</parameter> <type>text</type> )
27734 <returnvalue>void</returnvalue>
27735 </para>
27736 <para>
27737 Deletes a previously-created replication origin, including any
27738 associated replay progress.
27739 </para></entry>
27740 </row>
27742 <row>
27743 <entry role="func_table_entry"><para role="func_signature">
27744 <indexterm>
27745 <primary>pg_replication_origin_oid</primary>
27746 </indexterm>
27747 <function>pg_replication_origin_oid</function> ( <parameter>node_name</parameter> <type>text</type> )
27748 <returnvalue>oid</returnvalue>
27749 </para>
27750 <para>
27751 Looks up a replication origin by name and returns the internal ID. If
27752 no such replication origin is found, <literal>NULL</literal> is
27753 returned.
27754 </para></entry>
27755 </row>
27757 <row>
27758 <entry id="pg-replication-origin-session-setup" role="func_table_entry"><para role="func_signature">
27759 <indexterm>
27760 <primary>pg_replication_origin_session_setup</primary>
27761 </indexterm>
27762 <function>pg_replication_origin_session_setup</function> ( <parameter>node_name</parameter> <type>text</type> )
27763 <returnvalue>void</returnvalue>
27764 </para>
27765 <para>
27766 Marks the current session as replaying from the given
27767 origin, allowing replay progress to be tracked.
27768 Can only be used if no origin is currently selected.
27769 Use <function>pg_replication_origin_session_reset</function> to undo.
27770 </para></entry>
27771 </row>
27773 <row>
27774 <entry role="func_table_entry"><para role="func_signature">
27775 <indexterm>
27776 <primary>pg_replication_origin_session_reset</primary>
27777 </indexterm>
27778 <function>pg_replication_origin_session_reset</function> ()
27779 <returnvalue>void</returnvalue>
27780 </para>
27781 <para>
27782 Cancels the effects
27783 of <function>pg_replication_origin_session_setup()</function>.
27784 </para></entry>
27785 </row>
27787 <row>
27788 <entry role="func_table_entry"><para role="func_signature">
27789 <indexterm>
27790 <primary>pg_replication_origin_session_is_setup</primary>
27791 </indexterm>
27792 <function>pg_replication_origin_session_is_setup</function> ()
27793 <returnvalue>boolean</returnvalue>
27794 </para>
27795 <para>
27796 Returns true if a replication origin has been selected in the
27797 current session.
27798 </para></entry>
27799 </row>
27801 <row>
27802 <entry id="pg-replication-origin-session-progress" role="func_table_entry"><para role="func_signature">
27803 <indexterm>
27804 <primary>pg_replication_origin_session_progress</primary>
27805 </indexterm>
27806 <function>pg_replication_origin_session_progress</function> ( <parameter>flush</parameter> <type>boolean</type> )
27807 <returnvalue>pg_lsn</returnvalue>
27808 </para>
27809 <para>
27810 Returns the replay location for the replication origin selected in
27811 the current session. The parameter <parameter>flush</parameter>
27812 determines whether the corresponding local transaction will be
27813 guaranteed to have been flushed to disk or not.
27814 </para></entry>
27815 </row>
27817 <row>
27818 <entry id="pg-replication-origin-xact-setup" role="func_table_entry"><para role="func_signature">
27819 <indexterm>
27820 <primary>pg_replication_origin_xact_setup</primary>
27821 </indexterm>
27822 <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> )
27823 <returnvalue>void</returnvalue>
27824 </para>
27825 <para>
27826 Marks the current transaction as replaying a transaction that has
27827 committed at the given <acronym>LSN</acronym> and timestamp. Can
27828 only be called when a replication origin has been selected
27829 using <function>pg_replication_origin_session_setup</function>.
27830 </para></entry>
27831 </row>
27833 <row>
27834 <entry id="pg-replication-origin-xact-reset" role="func_table_entry"><para role="func_signature">
27835 <indexterm>
27836 <primary>pg_replication_origin_xact_reset</primary>
27837 </indexterm>
27838 <function>pg_replication_origin_xact_reset</function> ()
27839 <returnvalue>void</returnvalue>
27840 </para>
27841 <para>
27842 Cancels the effects of
27843 <function>pg_replication_origin_xact_setup()</function>.
27844 </para></entry>
27845 </row>
27847 <row>
27848 <entry id="pg-replication-origin-advance" role="func_table_entry"><para role="func_signature">
27849 <indexterm>
27850 <primary>pg_replication_origin_advance</primary>
27851 </indexterm>
27852 <function>pg_replication_origin_advance</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>lsn</parameter> <type>pg_lsn</type> )
27853 <returnvalue>void</returnvalue>
27854 </para>
27855 <para>
27856 Sets replication progress for the given node to the given
27857 location. This is primarily useful for setting up the initial
27858 location, or setting a new location after configuration changes and
27859 similar. Be aware that careless use of this function can lead to
27860 inconsistently replicated data.
27861 </para></entry>
27862 </row>
27864 <row>
27865 <entry id="pg-replication-origin-progress" role="func_table_entry"><para role="func_signature">
27866 <indexterm>
27867 <primary>pg_replication_origin_progress</primary>
27868 </indexterm>
27869 <function>pg_replication_origin_progress</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>boolean</type> )
27870 <returnvalue>pg_lsn</returnvalue>
27871 </para>
27872 <para>
27873 Returns the replay location for the given replication origin. The
27874 parameter <parameter>flush</parameter> determines whether the
27875 corresponding local transaction will be guaranteed to have been
27876 flushed to disk or not.
27877 </para></entry>
27878 </row>
27880 <row>
27881 <entry id="pg-logical-emit-message" role="func_table_entry"><para role="func_signature">
27882 <indexterm>
27883 <primary>pg_logical_emit_message</primary>
27884 </indexterm>
27885 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>text</type> [, <parameter>flush</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>false</literal>] )
27886 <returnvalue>pg_lsn</returnvalue>
27887 </para>
27888 <para role="func_signature">
27889 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>bytea</type> [, <parameter>flush</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>false</literal>] )
27890 <returnvalue>pg_lsn</returnvalue>
27891 </para>
27892 <para>
27893 Emits a logical decoding message. This can be used to pass generic
27894 messages to logical decoding plugins through
27895 WAL. The <parameter>transactional</parameter> parameter specifies if
27896 the message should be part of the current transaction, or if it should
27897 be written immediately and decoded as soon as the logical decoder
27898 reads the record. The <parameter>prefix</parameter> parameter is a
27899 textual prefix that can be used by logical decoding plugins to easily
27900 recognize messages that are interesting for them.
27901 The <parameter>content</parameter> parameter is the content of the
27902 message, given either in text or binary form.
27903 The <parameter>flush</parameter> parameter (default set to
27904 <literal>false</literal>) controls if the message is immediately
27905 flushed to WAL or not. <parameter>flush</parameter> has no effect
27906 with <parameter>transactional</parameter>, as the message's WAL
27907 record is flushed along with its transaction.
27908 </para></entry>
27909 </row>
27910 </tbody>
27911 </tgroup>
27912 </table>
27914 </sect2>
27916 <sect2 id="functions-admin-dbobject">
27917 <title>Database Object Management Functions</title>
27919 <para>
27920 The functions shown in <xref linkend="functions-admin-dbsize"/> calculate
27921 the disk space usage of database objects, or assist in presentation
27922 or understanding of usage results. <literal>bigint</literal> results
27923 are measured in bytes. If an OID that does
27924 not represent an existing object is passed to one of these
27925 functions, <literal>NULL</literal> is returned.
27926 </para>
27928 <table id="functions-admin-dbsize">
27929 <title>Database Object Size Functions</title>
27930 <tgroup cols="1">
27931 <thead>
27932 <row>
27933 <entry role="func_table_entry"><para role="func_signature">
27934 Function
27935 </para>
27936 <para>
27937 Description
27938 </para></entry>
27939 </row>
27940 </thead>
27942 <tbody>
27943 <row>
27944 <entry role="func_table_entry"><para role="func_signature">
27945 <indexterm>
27946 <primary>pg_column_size</primary>
27947 </indexterm>
27948 <function>pg_column_size</function> ( <type>"any"</type> )
27949 <returnvalue>integer</returnvalue>
27950 </para>
27951 <para>
27952 Shows the number of bytes used to store any individual data value. If
27953 applied directly to a table column value, this reflects any
27954 compression that was done.
27955 </para></entry>
27956 </row>
27958 <row>
27959 <entry role="func_table_entry"><para role="func_signature">
27960 <indexterm>
27961 <primary>pg_column_compression</primary>
27962 </indexterm>
27963 <function>pg_column_compression</function> ( <type>"any"</type> )
27964 <returnvalue>text</returnvalue>
27965 </para>
27966 <para>
27967 Shows the compression algorithm that was used to compress
27968 an individual variable-length value. Returns <literal>NULL</literal>
27969 if the value is not compressed.
27970 </para></entry>
27971 </row>
27973 <row>
27974 <entry role="func_table_entry"><para role="func_signature">
27975 <indexterm>
27976 <primary>pg_database_size</primary>
27977 </indexterm>
27978 <function>pg_database_size</function> ( <type>name</type> )
27979 <returnvalue>bigint</returnvalue>
27980 </para>
27981 <para role="func_signature">
27982 <function>pg_database_size</function> ( <type>oid</type> )
27983 <returnvalue>bigint</returnvalue>
27984 </para>
27985 <para>
27986 Computes the total disk space used by the database with the specified
27987 name or OID. To use this function, you must
27988 have <literal>CONNECT</literal> privilege on the specified database
27989 (which is granted by default) or have privileges of
27990 the <literal>pg_read_all_stats</literal> role.
27991 </para></entry>
27992 </row>
27994 <row>
27995 <entry role="func_table_entry"><para role="func_signature">
27996 <indexterm>
27997 <primary>pg_indexes_size</primary>
27998 </indexterm>
27999 <function>pg_indexes_size</function> ( <type>regclass</type> )
28000 <returnvalue>bigint</returnvalue>
28001 </para>
28002 <para>
28003 Computes the total disk space used by indexes attached to the
28004 specified table.
28005 </para></entry>
28006 </row>
28008 <row>
28009 <entry role="func_table_entry"><para role="func_signature">
28010 <indexterm>
28011 <primary>pg_relation_size</primary>
28012 </indexterm>
28013 <function>pg_relation_size</function> ( <parameter>relation</parameter> <type>regclass</type> <optional>, <parameter>fork</parameter> <type>text</type> </optional> )
28014 <returnvalue>bigint</returnvalue>
28015 </para>
28016 <para>
28017 Computes the disk space used by one <quote>fork</quote> of the
28018 specified relation. (Note that for most purposes it is more
28019 convenient to use the higher-level
28020 functions <function>pg_total_relation_size</function>
28021 or <function>pg_table_size</function>, which sum the sizes of all
28022 forks.) With one argument, this returns the size of the main data
28023 fork of the relation. The second argument can be provided to specify
28024 which fork to examine:
28025 <itemizedlist spacing="compact">
28026 <listitem>
28027 <para>
28028 <literal>main</literal> returns the size of the main
28029 data fork of the relation.
28030 </para>
28031 </listitem>
28032 <listitem>
28033 <para>
28034 <literal>fsm</literal> returns the size of the Free Space Map
28035 (see <xref linkend="storage-fsm"/>) associated with the relation.
28036 </para>
28037 </listitem>
28038 <listitem>
28039 <para>
28040 <literal>vm</literal> returns the size of the Visibility Map
28041 (see <xref linkend="storage-vm"/>) associated with the relation.
28042 </para>
28043 </listitem>
28044 <listitem>
28045 <para>
28046 <literal>init</literal> returns the size of the initialization
28047 fork, if any, associated with the relation.
28048 </para>
28049 </listitem>
28050 </itemizedlist>
28051 </para></entry>
28052 </row>
28054 <row>
28055 <entry role="func_table_entry"><para role="func_signature">
28056 <indexterm>
28057 <primary>pg_size_bytes</primary>
28058 </indexterm>
28059 <function>pg_size_bytes</function> ( <type>text</type> )
28060 <returnvalue>bigint</returnvalue>
28061 </para>
28062 <para>
28063 Converts a size in human-readable format (as returned
28064 by <function>pg_size_pretty</function>) into bytes. Valid units are
28065 <literal>bytes</literal>, <literal>B</literal>, <literal>kB</literal>,
28066 <literal>MB</literal>, <literal>GB</literal>, <literal>TB</literal>,
28067 and <literal>PB</literal>.
28068 </para></entry>
28069 </row>
28071 <row>
28072 <entry role="func_table_entry"><para role="func_signature">
28073 <indexterm>
28074 <primary>pg_size_pretty</primary>
28075 </indexterm>
28076 <function>pg_size_pretty</function> ( <type>bigint</type> )
28077 <returnvalue>text</returnvalue>
28078 </para>
28079 <para role="func_signature">
28080 <function>pg_size_pretty</function> ( <type>numeric</type> )
28081 <returnvalue>text</returnvalue>
28082 </para>
28083 <para>
28084 Converts a size in bytes into a more easily human-readable format with
28085 size units (bytes, kB, MB, GB, TB, or PB as appropriate). Note that the
28086 units are powers of 2 rather than powers of 10, so 1kB is 1024 bytes,
28087 1MB is 1024<superscript>2</superscript> = 1048576 bytes, and so on.
28088 </para></entry>
28089 </row>
28091 <row>
28092 <entry role="func_table_entry"><para role="func_signature">
28093 <indexterm>
28094 <primary>pg_table_size</primary>
28095 </indexterm>
28096 <function>pg_table_size</function> ( <type>regclass</type> )
28097 <returnvalue>bigint</returnvalue>
28098 </para>
28099 <para>
28100 Computes the disk space used by the specified table, excluding indexes
28101 (but including its TOAST table if any, free space map, and visibility
28102 map).
28103 </para></entry>
28104 </row>
28106 <row>
28107 <entry role="func_table_entry"><para role="func_signature">
28108 <indexterm>
28109 <primary>pg_tablespace_size</primary>
28110 </indexterm>
28111 <function>pg_tablespace_size</function> ( <type>name</type> )
28112 <returnvalue>bigint</returnvalue>
28113 </para>
28114 <para role="func_signature">
28115 <function>pg_tablespace_size</function> ( <type>oid</type> )
28116 <returnvalue>bigint</returnvalue>
28117 </para>
28118 <para>
28119 Computes the total disk space used in the tablespace with the
28120 specified name or OID. To use this function, you must
28121 have <literal>CREATE</literal> privilege on the specified tablespace
28122 or have privileges of the <literal>pg_read_all_stats</literal> role,
28123 unless it is the default tablespace for the current database.
28124 </para></entry>
28125 </row>
28127 <row>
28128 <entry role="func_table_entry"><para role="func_signature">
28129 <indexterm>
28130 <primary>pg_total_relation_size</primary>
28131 </indexterm>
28132 <function>pg_total_relation_size</function> ( <type>regclass</type> )
28133 <returnvalue>bigint</returnvalue>
28134 </para>
28135 <para>
28136 Computes the total disk space used by the specified table, including
28137 all indexes and <acronym>TOAST</acronym> data. The result is
28138 equivalent to <function>pg_table_size</function>
28139 <literal>+</literal> <function>pg_indexes_size</function>.
28140 </para></entry>
28141 </row>
28142 </tbody>
28143 </tgroup>
28144 </table>
28146 <para>
28147 The functions above that operate on tables or indexes accept a
28148 <type>regclass</type> argument, which is simply the OID of the table or index
28149 in the <structname>pg_class</structname> system catalog. You do not have to look up
28150 the OID by hand, however, since the <type>regclass</type> data type's input
28151 converter will do the work for you. See <xref linkend="datatype-oid"/>
28152 for details.
28153 </para>
28155 <para>
28156 The functions shown in <xref linkend="functions-admin-dblocation"/> assist
28157 in identifying the specific disk files associated with database objects.
28158 </para>
28160 <table id="functions-admin-dblocation">
28161 <title>Database Object Location Functions</title>
28162 <tgroup cols="1">
28163 <thead>
28164 <row>
28165 <entry role="func_table_entry"><para role="func_signature">
28166 Function
28167 </para>
28168 <para>
28169 Description
28170 </para></entry>
28171 </row>
28172 </thead>
28174 <tbody>
28175 <row>
28176 <entry role="func_table_entry"><para role="func_signature">
28177 <indexterm>
28178 <primary>pg_relation_filenode</primary>
28179 </indexterm>
28180 <function>pg_relation_filenode</function> ( <parameter>relation</parameter> <type>regclass</type> )
28181 <returnvalue>oid</returnvalue>
28182 </para>
28183 <para>
28184 Returns the <quote>filenode</quote> number currently assigned to the
28185 specified relation. The filenode is the base component of the file
28186 name(s) used for the relation (see
28187 <xref linkend="storage-file-layout"/> for more information).
28188 For most relations the result is the same as
28189 <structname>pg_class</structname>.<structfield>relfilenode</structfield>,
28190 but for certain system catalogs <structfield>relfilenode</structfield>
28191 is zero and this function must be used to get the correct value. The
28192 function returns NULL if passed a relation that does not have storage,
28193 such as a view.
28194 </para></entry>
28195 </row>
28197 <row>
28198 <entry role="func_table_entry"><para role="func_signature">
28199 <indexterm>
28200 <primary>pg_relation_filepath</primary>
28201 </indexterm>
28202 <function>pg_relation_filepath</function> ( <parameter>relation</parameter> <type>regclass</type> )
28203 <returnvalue>text</returnvalue>
28204 </para>
28205 <para>
28206 Returns the entire file path name (relative to the database cluster's
28207 data directory, <varname>PGDATA</varname>) of the relation.
28208 </para></entry>
28209 </row>
28211 <row>
28212 <entry role="func_table_entry"><para role="func_signature">
28213 <indexterm>
28214 <primary>pg_filenode_relation</primary>
28215 </indexterm>
28216 <function>pg_filenode_relation</function> ( <parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type> )
28217 <returnvalue>regclass</returnvalue>
28218 </para>
28219 <para>
28220 Returns a relation's OID given the tablespace OID and filenode it is
28221 stored under. This is essentially the inverse mapping of
28222 <function>pg_relation_filepath</function>. For a relation in the
28223 database's default tablespace, the tablespace can be specified as zero.
28224 Returns <literal>NULL</literal> if no relation in the current database
28225 is associated with the given values.
28226 </para></entry>
28227 </row>
28228 </tbody>
28229 </tgroup>
28230 </table>
28232 <para>
28233 <xref linkend="functions-admin-collation"/> lists functions used to manage
28234 collations.
28235 </para>
28237 <table id="functions-admin-collation">
28238 <title>Collation Management Functions</title>
28239 <tgroup cols="1">
28240 <thead>
28241 <row>
28242 <entry role="func_table_entry"><para role="func_signature">
28243 Function
28244 </para>
28245 <para>
28246 Description
28247 </para></entry>
28248 </row>
28249 </thead>
28251 <tbody>
28252 <row>
28253 <entry role="func_table_entry"><para role="func_signature">
28254 <indexterm>
28255 <primary>pg_collation_actual_version</primary>
28256 </indexterm>
28257 <function>pg_collation_actual_version</function> ( <type>oid</type> )
28258 <returnvalue>text</returnvalue>
28259 </para>
28260 <para>
28261 Returns the actual version of the collation object as it is currently
28262 installed in the operating system. If this is different from the
28263 value in
28264 <structname>pg_collation</structname>.<structfield>collversion</structfield>,
28265 then objects depending on the collation might need to be rebuilt. See
28266 also <xref linkend="sql-altercollation"/>.
28267 </para></entry>
28268 </row>
28270 <row>
28271 <entry role="func_table_entry"><para role="func_signature">
28272 <indexterm>
28273 <primary>pg_database_collation_actual_version</primary>
28274 </indexterm>
28275 <function>pg_database_collation_actual_version</function> ( <type>oid</type> )
28276 <returnvalue>text</returnvalue>
28277 </para>
28278 <para>
28279 Returns the actual version of the database's collation as it is currently
28280 installed in the operating system. If this is different from the
28281 value in
28282 <structname>pg_database</structname>.<structfield>datcollversion</structfield>,
28283 then objects depending on the collation might need to be rebuilt. See
28284 also <xref linkend="sql-alterdatabase"/>.
28285 </para></entry>
28286 </row>
28288 <row>
28289 <entry role="func_table_entry"><para role="func_signature">
28290 <indexterm>
28291 <primary>pg_import_system_collations</primary>
28292 </indexterm>
28293 <function>pg_import_system_collations</function> ( <parameter>schema</parameter> <type>regnamespace</type> )
28294 <returnvalue>integer</returnvalue>
28295 </para>
28296 <para>
28297 Adds collations to the system
28298 catalog <structname>pg_collation</structname> based on all the locales
28299 it finds in the operating system. This is
28300 what <command>initdb</command> uses; see
28301 <xref linkend="collation-managing"/> for more details. If additional
28302 locales are installed into the operating system later on, this
28303 function can be run again to add collations for the new locales.
28304 Locales that match existing entries
28305 in <structname>pg_collation</structname> will be skipped. (But
28306 collation objects based on locales that are no longer present in the
28307 operating system are not removed by this function.)
28308 The <parameter>schema</parameter> parameter would typically
28309 be <literal>pg_catalog</literal>, but that is not a requirement; the
28310 collations could be installed into some other schema as well. The
28311 function returns the number of new collation objects it created.
28312 Use of this function is restricted to superusers.
28313 </para></entry>
28314 </row>
28315 </tbody>
28316 </tgroup>
28317 </table>
28319 <para>
28320 <xref linkend="functions-info-partition"/> lists functions that provide
28321 information about the structure of partitioned tables.
28322 </para>
28324 <table id="functions-info-partition">
28325 <title>Partitioning Information Functions</title>
28326 <tgroup cols="1">
28327 <thead>
28328 <row>
28329 <entry role="func_table_entry"><para role="func_signature">
28330 Function
28331 </para>
28332 <para>
28333 Description
28334 </para></entry>
28335 </row>
28336 </thead>
28338 <tbody>
28339 <row>
28340 <entry role="func_table_entry"><para role="func_signature">
28341 <indexterm>
28342 <primary>pg_partition_tree</primary>
28343 </indexterm>
28344 <function>pg_partition_tree</function> ( <type>regclass</type> )
28345 <returnvalue>setof record</returnvalue>
28346 ( <parameter>relid</parameter> <type>regclass</type>,
28347 <parameter>parentrelid</parameter> <type>regclass</type>,
28348 <parameter>isleaf</parameter> <type>boolean</type>,
28349 <parameter>level</parameter> <type>integer</type> )
28350 </para>
28351 <para>
28352 Lists the tables or indexes in the partition tree of the
28353 given partitioned table or partitioned index, with one row for each
28354 partition. Information provided includes the OID of the partition,
28355 the OID of its immediate parent, a boolean value telling if the
28356 partition is a leaf, and an integer telling its level in the hierarchy.
28357 The level value is 0 for the input table or index, 1 for its
28358 immediate child partitions, 2 for their partitions, and so on.
28359 Returns no rows if the relation does not exist or is not a partition
28360 or partitioned table.
28361 </para></entry>
28362 </row>
28364 <row>
28365 <entry role="func_table_entry"><para role="func_signature">
28366 <indexterm>
28367 <primary>pg_partition_ancestors</primary>
28368 </indexterm>
28369 <function>pg_partition_ancestors</function> ( <type>regclass</type> )
28370 <returnvalue>setof regclass</returnvalue>
28371 </para>
28372 <para>
28373 Lists the ancestor relations of the given partition,
28374 including the relation itself. Returns no rows if the relation
28375 does not exist or is not a partition or partitioned table.
28376 </para></entry>
28377 </row>
28379 <row>
28380 <entry role="func_table_entry"><para role="func_signature">
28381 <indexterm>
28382 <primary>pg_partition_root</primary>
28383 </indexterm>
28384 <function>pg_partition_root</function> ( <type>regclass</type> )
28385 <returnvalue>regclass</returnvalue>
28386 </para>
28387 <para>
28388 Returns the top-most parent of the partition tree to which the given
28389 relation belongs. Returns <literal>NULL</literal> if the relation
28390 does not exist or is not a partition or partitioned table.
28391 </para></entry>
28392 </row>
28393 </tbody>
28394 </tgroup>
28395 </table>
28397 <para>
28398 For example, to check the total size of the data contained in a
28399 partitioned table <structname>measurement</structname>, one could use the
28400 following query:
28401 <programlisting>
28402 SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
28403 FROM pg_partition_tree('measurement');
28404 </programlisting>
28405 </para>
28407 </sect2>
28409 <sect2 id="functions-admin-index">
28410 <title>Index Maintenance Functions</title>
28412 <para>
28413 <xref linkend="functions-admin-index-table"/> shows the functions
28414 available for index maintenance tasks. (Note that these maintenance
28415 tasks are normally done automatically by autovacuum; use of these
28416 functions is only required in special cases.)
28417 These functions cannot be executed during recovery.
28418 Use of these functions is restricted to superusers and the owner
28419 of the given index.
28420 </para>
28422 <table id="functions-admin-index-table">
28423 <title>Index Maintenance Functions</title>
28424 <tgroup cols="1">
28425 <thead>
28426 <row>
28427 <entry role="func_table_entry"><para role="func_signature">
28428 Function
28429 </para>
28430 <para>
28431 Description
28432 </para></entry>
28433 </row>
28434 </thead>
28436 <tbody>
28437 <row>
28438 <entry role="func_table_entry"><para role="func_signature">
28439 <indexterm>
28440 <primary>brin_summarize_new_values</primary>
28441 </indexterm>
28442 <function>brin_summarize_new_values</function> ( <parameter>index</parameter> <type>regclass</type> )
28443 <returnvalue>integer</returnvalue>
28444 </para>
28445 <para>
28446 Scans the specified BRIN index to find page ranges in the base table
28447 that are not currently summarized by the index; for any such range it
28448 creates a new summary index tuple by scanning those table pages.
28449 Returns the number of new page range summaries that were inserted
28450 into the index.
28451 </para></entry>
28452 </row>
28454 <row>
28455 <entry role="func_table_entry"><para role="func_signature">
28456 <indexterm>
28457 <primary>brin_summarize_range</primary>
28458 </indexterm>
28459 <function>brin_summarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
28460 <returnvalue>integer</returnvalue>
28461 </para>
28462 <para>
28463 Summarizes the page range covering the given block, if not already
28464 summarized. This is
28465 like <function>brin_summarize_new_values</function> except that it
28466 only processes the page range that covers the given table block number.
28467 </para></entry>
28468 </row>
28470 <row>
28471 <entry role="func_table_entry"><para role="func_signature">
28472 <indexterm>
28473 <primary>brin_desummarize_range</primary>
28474 </indexterm>
28475 <function>brin_desummarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
28476 <returnvalue>void</returnvalue>
28477 </para>
28478 <para>
28479 Removes the BRIN index tuple that summarizes the page range covering
28480 the given table block, if there is one.
28481 </para></entry>
28482 </row>
28484 <row>
28485 <entry role="func_table_entry"><para role="func_signature">
28486 <indexterm>
28487 <primary>gin_clean_pending_list</primary>
28488 </indexterm>
28489 <function>gin_clean_pending_list</function> ( <parameter>index</parameter> <type>regclass</type> )
28490 <returnvalue>bigint</returnvalue>
28491 </para>
28492 <para>
28493 Cleans up the <quote>pending</quote> list of the specified GIN index
28494 by moving entries in it, in bulk, to the main GIN data structure.
28495 Returns the number of pages removed from the pending list.
28496 If the argument is a GIN index built with
28497 the <literal>fastupdate</literal> option disabled, no cleanup happens
28498 and the result is zero, because the index doesn't have a pending list.
28499 See <xref linkend="gin-fast-update"/> and <xref linkend="gin-tips"/>
28500 for details about the pending list and <literal>fastupdate</literal>
28501 option.
28502 </para></entry>
28503 </row>
28504 </tbody>
28505 </tgroup>
28506 </table>
28508 </sect2>
28510 <sect2 id="functions-admin-genfile">
28511 <title>Generic File Access Functions</title>
28513 <para>
28514 The functions shown in <xref
28515 linkend="functions-admin-genfile-table"/> provide native access to
28516 files on the machine hosting the server. Only files within the
28517 database cluster directory and the <varname>log_directory</varname> can be
28518 accessed, unless the user is a superuser or is granted the role
28519 <literal>pg_read_server_files</literal>. Use a relative path for files in
28520 the cluster directory, and a path matching the <varname>log_directory</varname>
28521 configuration setting for log files.
28522 </para>
28524 <para>
28525 Note that granting users the EXECUTE privilege on
28526 <function>pg_read_file()</function>, or related functions, allows them the
28527 ability to read any file on the server that the database server process can
28528 read; these functions bypass all in-database privilege checks. This means
28529 that, for example, a user with such access is able to read the contents of
28530 the <structname>pg_authid</structname> table where authentication
28531 information is stored, as well as read any table data in the database.
28532 Therefore, granting access to these functions should be carefully
28533 considered.
28534 </para>
28536 <para>
28537 When granting privilege on these functions, note that the table entries
28538 showing optional parameters are mostly implemented as several physical
28539 functions with different parameter lists. Privilege must be granted
28540 separately on each such function, if it is to be
28541 used. <application>psql</application>'s <command>\df</command> command
28542 can be useful to check what the actual function signatures are.
28543 </para>
28545 <para>
28546 Some of these functions take an optional <parameter>missing_ok</parameter>
28547 parameter, which specifies the behavior when the file or directory does
28548 not exist. If <literal>true</literal>, the function
28549 returns <literal>NULL</literal> or an empty result set, as appropriate.
28550 If <literal>false</literal>, an error is raised. (Failure conditions
28551 other than <quote>file not found</quote> are reported as errors in any
28552 case.) The default is <literal>false</literal>.
28553 </para>
28555 <table id="functions-admin-genfile-table">
28556 <title>Generic File Access Functions</title>
28557 <tgroup cols="1">
28558 <thead>
28559 <row>
28560 <entry role="func_table_entry"><para role="func_signature">
28561 Function
28562 </para>
28563 <para>
28564 Description
28565 </para></entry>
28566 </row>
28567 </thead>
28569 <tbody>
28570 <row>
28571 <entry role="func_table_entry"><para role="func_signature">
28572 <indexterm>
28573 <primary>pg_ls_dir</primary>
28574 </indexterm>
28575 <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> )
28576 <returnvalue>setof text</returnvalue>
28577 </para>
28578 <para>
28579 Returns the names of all files (and directories and other special
28580 files) in the specified
28581 directory. The <parameter>include_dot_dirs</parameter> parameter
28582 indicates whether <quote>.</quote> and <quote>..</quote> are to be
28583 included in the result set; the default is to exclude them. Including
28584 them can be useful when <parameter>missing_ok</parameter>
28585 is <literal>true</literal>, to distinguish an empty directory from a
28586 non-existent directory.
28587 </para>
28588 <para>
28589 This function is restricted to superusers by default, but other users
28590 can be granted EXECUTE to run the function.
28591 </para></entry>
28592 </row>
28594 <row>
28595 <entry role="func_table_entry"><para role="func_signature">
28596 <indexterm>
28597 <primary>pg_ls_logdir</primary>
28598 </indexterm>
28599 <function>pg_ls_logdir</function> ()
28600 <returnvalue>setof record</returnvalue>
28601 ( <parameter>name</parameter> <type>text</type>,
28602 <parameter>size</parameter> <type>bigint</type>,
28603 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28604 </para>
28605 <para>
28606 Returns the name, size, and last modification time (mtime) of each
28607 ordinary file in the server's log directory. Filenames beginning with
28608 a dot, directories, and other special files are excluded.
28609 </para>
28610 <para>
28611 This function is restricted to superusers and roles with privileges of
28612 the <literal>pg_monitor</literal> role by default, but other users can
28613 be granted EXECUTE to run the function.
28614 </para></entry>
28615 </row>
28617 <row>
28618 <entry role="func_table_entry"><para role="func_signature">
28619 <indexterm>
28620 <primary>pg_ls_waldir</primary>
28621 </indexterm>
28622 <function>pg_ls_waldir</function> ()
28623 <returnvalue>setof record</returnvalue>
28624 ( <parameter>name</parameter> <type>text</type>,
28625 <parameter>size</parameter> <type>bigint</type>,
28626 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28627 </para>
28628 <para>
28629 Returns the name, size, and last modification time (mtime) of each
28630 ordinary file in the server's write-ahead log (WAL) directory.
28631 Filenames beginning with a dot, directories, and other special files
28632 are excluded.
28633 </para>
28634 <para>
28635 This function is restricted to superusers and roles with privileges of
28636 the <literal>pg_monitor</literal> role by default, but other users can
28637 be granted EXECUTE to run the function.
28638 </para></entry>
28639 </row>
28641 <row>
28642 <entry role="func_table_entry"><para role="func_signature">
28643 <indexterm>
28644 <primary>pg_ls_logicalmapdir</primary>
28645 </indexterm>
28646 <function>pg_ls_logicalmapdir</function> ()
28647 <returnvalue>setof record</returnvalue>
28648 ( <parameter>name</parameter> <type>text</type>,
28649 <parameter>size</parameter> <type>bigint</type>,
28650 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28651 </para>
28652 <para>
28653 Returns the name, size, and last modification time (mtime) of each
28654 ordinary file in the server's <filename>pg_logical/mappings</filename>
28655 directory. Filenames beginning with a dot, directories, and other
28656 special files are excluded.
28657 </para>
28658 <para>
28659 This function is restricted to superusers and members of
28660 the <literal>pg_monitor</literal> role by default, but other users can
28661 be granted EXECUTE to run the function.
28662 </para></entry>
28663 </row>
28665 <row>
28666 <entry role="func_table_entry"><para role="func_signature">
28667 <indexterm>
28668 <primary>pg_ls_logicalsnapdir</primary>
28669 </indexterm>
28670 <function>pg_ls_logicalsnapdir</function> ()
28671 <returnvalue>setof record</returnvalue>
28672 ( <parameter>name</parameter> <type>text</type>,
28673 <parameter>size</parameter> <type>bigint</type>,
28674 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28675 </para>
28676 <para>
28677 Returns the name, size, and last modification time (mtime) of each
28678 ordinary file in the server's <filename>pg_logical/snapshots</filename>
28679 directory. Filenames beginning with a dot, directories, and other
28680 special files are excluded.
28681 </para>
28682 <para>
28683 This function is restricted to superusers and members of
28684 the <literal>pg_monitor</literal> role by default, but other users can
28685 be granted EXECUTE to run the function.
28686 </para></entry>
28687 </row>
28689 <row>
28690 <entry role="func_table_entry"><para role="func_signature">
28691 <indexterm>
28692 <primary>pg_ls_replslotdir</primary>
28693 </indexterm>
28694 <function>pg_ls_replslotdir</function> ( <parameter>slot_name</parameter> <type>text</type> )
28695 <returnvalue>setof record</returnvalue>
28696 ( <parameter>name</parameter> <type>text</type>,
28697 <parameter>size</parameter> <type>bigint</type>,
28698 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28699 </para>
28700 <para>
28701 Returns the name, size, and last modification time (mtime) of each
28702 ordinary file in the server's <filename>pg_replslot/slot_name</filename>
28703 directory, where <parameter>slot_name</parameter> is the name of the
28704 replication slot provided as input of the function. Filenames beginning
28705 with a dot, directories, and other special files are excluded.
28706 </para>
28707 <para>
28708 This function is restricted to superusers and members of
28709 the <literal>pg_monitor</literal> role by default, but other users can
28710 be granted EXECUTE to run the function.
28711 </para></entry>
28712 </row>
28714 <row>
28715 <entry role="func_table_entry"><para role="func_signature">
28716 <indexterm>
28717 <primary>pg_ls_archive_statusdir</primary>
28718 </indexterm>
28719 <function>pg_ls_archive_statusdir</function> ()
28720 <returnvalue>setof record</returnvalue>
28721 ( <parameter>name</parameter> <type>text</type>,
28722 <parameter>size</parameter> <type>bigint</type>,
28723 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28724 </para>
28725 <para>
28726 Returns the name, size, and last modification time (mtime) of each
28727 ordinary file in the server's WAL archive status directory
28728 (<filename>pg_wal/archive_status</filename>). Filenames beginning
28729 with a dot, directories, and other special files are excluded.
28730 </para>
28731 <para>
28732 This function is restricted to superusers and members of
28733 the <literal>pg_monitor</literal> role by default, but other users can
28734 be granted EXECUTE to run the function.
28735 </para></entry>
28736 </row>
28738 <row>
28739 <entry role="func_table_entry"><para role="func_signature">
28741 <indexterm>
28742 <primary>pg_ls_tmpdir</primary>
28743 </indexterm>
28744 <function>pg_ls_tmpdir</function> ( <optional> <parameter>tablespace</parameter> <type>oid</type> </optional> )
28745 <returnvalue>setof record</returnvalue>
28746 ( <parameter>name</parameter> <type>text</type>,
28747 <parameter>size</parameter> <type>bigint</type>,
28748 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28749 </para>
28750 <para>
28751 Returns the name, size, and last modification time (mtime) of each
28752 ordinary file in the temporary file directory for the
28753 specified <parameter>tablespace</parameter>.
28754 If <parameter>tablespace</parameter> is not provided,
28755 the <literal>pg_default</literal> tablespace is examined. Filenames
28756 beginning with a dot, directories, and other special files are
28757 excluded.
28758 </para>
28759 <para>
28760 This function is restricted to superusers and members of
28761 the <literal>pg_monitor</literal> role by default, but other users can
28762 be granted EXECUTE to run the function.
28763 </para></entry>
28764 </row>
28766 <row>
28767 <entry role="func_table_entry"><para role="func_signature">
28768 <indexterm>
28769 <primary>pg_read_file</primary>
28770 </indexterm>
28771 <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> )
28772 <returnvalue>text</returnvalue>
28773 </para>
28774 <para>
28775 Returns all or part of a text file, starting at the
28776 given byte <parameter>offset</parameter>, returning at
28777 most <parameter>length</parameter> bytes (less if the end of file is
28778 reached first). If <parameter>offset</parameter> is negative, it is
28779 relative to the end of the file. If <parameter>offset</parameter>
28780 and <parameter>length</parameter> are omitted, the entire file is
28781 returned. The bytes read from the file are interpreted as a string in
28782 the database's encoding; an error is thrown if they are not valid in
28783 that encoding.
28784 </para>
28785 <para>
28786 This function is restricted to superusers by default, but other users
28787 can be granted EXECUTE to run the function.
28788 </para></entry>
28789 </row>
28791 <row>
28792 <entry role="func_table_entry"><para role="func_signature">
28793 <indexterm>
28794 <primary>pg_read_binary_file</primary>
28795 </indexterm>
28796 <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> )
28797 <returnvalue>bytea</returnvalue>
28798 </para>
28799 <para>
28800 Returns all or part of a file. This function is identical to
28801 <function>pg_read_file</function> except that it can read arbitrary
28802 binary data, returning the result as <type>bytea</type>
28803 not <type>text</type>; accordingly, no encoding checks are performed.
28804 </para>
28805 <para>
28806 This function is restricted to superusers by default, but other users
28807 can be granted EXECUTE to run the function.
28808 </para>
28809 <para>
28810 In combination with the <function>convert_from</function> function,
28811 this function can be used to read a text file in a specified encoding
28812 and convert to the database's encoding:
28813 <programlisting>
28814 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
28815 </programlisting>
28816 </para></entry>
28817 </row>
28819 <row>
28820 <entry role="func_table_entry"><para role="func_signature">
28821 <indexterm>
28822 <primary>pg_stat_file</primary>
28823 </indexterm>
28824 <function>pg_stat_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
28825 <returnvalue>record</returnvalue>
28826 ( <parameter>size</parameter> <type>bigint</type>,
28827 <parameter>access</parameter> <type>timestamp with time zone</type>,
28828 <parameter>modification</parameter> <type>timestamp with time zone</type>,
28829 <parameter>change</parameter> <type>timestamp with time zone</type>,
28830 <parameter>creation</parameter> <type>timestamp with time zone</type>,
28831 <parameter>isdir</parameter> <type>boolean</type> )
28832 </para>
28833 <para>
28834 Returns a record containing the file's size, last access time stamp,
28835 last modification time stamp, last file status change time stamp (Unix
28836 platforms only), file creation time stamp (Windows only), and a flag
28837 indicating if it is a directory.
28838 </para>
28839 <para>
28840 This function is restricted to superusers by default, but other users
28841 can be granted EXECUTE to run the function.
28842 </para></entry>
28843 </row>
28845 </tbody>
28846 </tgroup>
28847 </table>
28849 </sect2>
28851 <sect2 id="functions-advisory-locks">
28852 <title>Advisory Lock Functions</title>
28854 <para>
28855 The functions shown in <xref linkend="functions-advisory-locks-table"/>
28856 manage advisory locks. For details about proper use of these functions,
28857 see <xref linkend="advisory-locks"/>.
28858 </para>
28860 <para>
28861 All these functions are intended to be used to lock application-defined
28862 resources, which can be identified either by a single 64-bit key value or
28863 two 32-bit key values (note that these two key spaces do not overlap).
28864 If another session already holds a conflicting lock on the same resource
28865 identifier, the functions will either wait until the resource becomes
28866 available, or return a <literal>false</literal> result, as appropriate for
28867 the function.
28868 Locks can be either shared or exclusive: a shared lock does not conflict
28869 with other shared locks on the same resource, only with exclusive locks.
28870 Locks can be taken at session level (so that they are held until released
28871 or the session ends) or at transaction level (so that they are held until
28872 the current transaction ends; there is no provision for manual release).
28873 Multiple session-level lock requests stack, so that if the same resource
28874 identifier is locked three times there must then be three unlock requests
28875 to release the resource in advance of session end.
28876 </para>
28878 <table id="functions-advisory-locks-table">
28879 <title>Advisory Lock Functions</title>
28880 <tgroup cols="1">
28881 <thead>
28882 <row>
28883 <entry role="func_table_entry"><para role="func_signature">
28884 Function
28885 </para>
28886 <para>
28887 Description
28888 </para></entry>
28889 </row>
28890 </thead>
28892 <tbody>
28893 <row>
28894 <entry role="func_table_entry"><para role="func_signature">
28895 <indexterm>
28896 <primary>pg_advisory_lock</primary>
28897 </indexterm>
28898 <function>pg_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28899 <returnvalue>void</returnvalue>
28900 </para>
28901 <para role="func_signature">
28902 <function>pg_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28903 <returnvalue>void</returnvalue>
28904 </para>
28905 <para>
28906 Obtains an exclusive session-level advisory lock, waiting if necessary.
28907 </para></entry>
28908 </row>
28910 <row>
28911 <entry role="func_table_entry"><para role="func_signature">
28912 <indexterm>
28913 <primary>pg_advisory_lock_shared</primary>
28914 </indexterm>
28915 <function>pg_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28916 <returnvalue>void</returnvalue>
28917 </para>
28918 <para role="func_signature">
28919 <function>pg_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28920 <returnvalue>void</returnvalue>
28921 </para>
28922 <para>
28923 Obtains a shared session-level advisory lock, waiting if necessary.
28924 </para></entry>
28925 </row>
28927 <row>
28928 <entry role="func_table_entry"><para role="func_signature">
28929 <indexterm>
28930 <primary>pg_advisory_unlock</primary>
28931 </indexterm>
28932 <function>pg_advisory_unlock</function> ( <parameter>key</parameter> <type>bigint</type> )
28933 <returnvalue>boolean</returnvalue>
28934 </para>
28935 <para role="func_signature">
28936 <function>pg_advisory_unlock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28937 <returnvalue>boolean</returnvalue>
28938 </para>
28939 <para>
28940 Releases a previously-acquired exclusive session-level advisory lock.
28941 Returns <literal>true</literal> if the lock is successfully released.
28942 If the lock was not held, <literal>false</literal> is returned, and in
28943 addition, an SQL warning will be reported by the server.
28944 </para></entry>
28945 </row>
28947 <row>
28948 <entry role="func_table_entry"><para role="func_signature">
28949 <indexterm>
28950 <primary>pg_advisory_unlock_all</primary>
28951 </indexterm>
28952 <function>pg_advisory_unlock_all</function> ()
28953 <returnvalue>void</returnvalue>
28954 </para>
28955 <para>
28956 Releases all session-level advisory locks held by the current session.
28957 (This function is implicitly invoked at session end, even if the
28958 client disconnects ungracefully.)
28959 </para></entry>
28960 </row>
28962 <row>
28963 <entry role="func_table_entry"><para role="func_signature">
28964 <indexterm>
28965 <primary>pg_advisory_unlock_shared</primary>
28966 </indexterm>
28967 <function>pg_advisory_unlock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28968 <returnvalue>boolean</returnvalue>
28969 </para>
28970 <para role="func_signature">
28971 <function>pg_advisory_unlock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28972 <returnvalue>boolean</returnvalue>
28973 </para>
28974 <para>
28975 Releases a previously-acquired shared session-level advisory lock.
28976 Returns <literal>true</literal> if the lock is successfully released.
28977 If the lock was not held, <literal>false</literal> is returned, and in
28978 addition, an SQL warning will be reported by the server.
28979 </para></entry>
28980 </row>
28982 <row>
28983 <entry role="func_table_entry"><para role="func_signature">
28984 <indexterm>
28985 <primary>pg_advisory_xact_lock</primary>
28986 </indexterm>
28987 <function>pg_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28988 <returnvalue>void</returnvalue>
28989 </para>
28990 <para role="func_signature">
28991 <function>pg_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28992 <returnvalue>void</returnvalue>
28993 </para>
28994 <para>
28995 Obtains an exclusive transaction-level advisory lock, waiting if
28996 necessary.
28997 </para></entry>
28998 </row>
29000 <row>
29001 <entry role="func_table_entry"><para role="func_signature">
29002 <indexterm>
29003 <primary>pg_advisory_xact_lock_shared</primary>
29004 </indexterm>
29005 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
29006 <returnvalue>void</returnvalue>
29007 </para>
29008 <para role="func_signature">
29009 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
29010 <returnvalue>void</returnvalue>
29011 </para>
29012 <para>
29013 Obtains a shared transaction-level advisory lock, waiting if
29014 necessary.
29015 </para></entry>
29016 </row>
29018 <row>
29019 <entry role="func_table_entry"><para role="func_signature">
29020 <indexterm>
29021 <primary>pg_try_advisory_lock</primary>
29022 </indexterm>
29023 <function>pg_try_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
29024 <returnvalue>boolean</returnvalue>
29025 </para>
29026 <para role="func_signature">
29027 <function>pg_try_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
29028 <returnvalue>boolean</returnvalue>
29029 </para>
29030 <para>
29031 Obtains an exclusive session-level advisory lock if available.
29032 This will either obtain the lock immediately and
29033 return <literal>true</literal>, or return <literal>false</literal>
29034 without waiting if the lock cannot be acquired immediately.
29035 </para></entry>
29036 </row>
29038 <row>
29039 <entry role="func_table_entry"><para role="func_signature">
29040 <indexterm>
29041 <primary>pg_try_advisory_lock_shared</primary>
29042 </indexterm>
29043 <function>pg_try_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
29044 <returnvalue>boolean</returnvalue>
29045 </para>
29046 <para role="func_signature">
29047 <function>pg_try_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
29048 <returnvalue>boolean</returnvalue>
29049 </para>
29050 <para>
29051 Obtains a shared session-level advisory lock if available.
29052 This will either obtain the lock immediately and
29053 return <literal>true</literal>, or return <literal>false</literal>
29054 without waiting if the lock cannot be acquired immediately.
29055 </para></entry>
29056 </row>
29058 <row>
29059 <entry role="func_table_entry"><para role="func_signature">
29060 <indexterm>
29061 <primary>pg_try_advisory_xact_lock</primary>
29062 </indexterm>
29063 <function>pg_try_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
29064 <returnvalue>boolean</returnvalue>
29065 </para>
29066 <para role="func_signature">
29067 <function>pg_try_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
29068 <returnvalue>boolean</returnvalue>
29069 </para>
29070 <para>
29071 Obtains an exclusive transaction-level advisory lock if available.
29072 This will either obtain the lock immediately and
29073 return <literal>true</literal>, or return <literal>false</literal>
29074 without waiting if the lock cannot be acquired immediately.
29075 </para></entry>
29076 </row>
29078 <row>
29079 <entry role="func_table_entry"><para role="func_signature">
29080 <indexterm>
29081 <primary>pg_try_advisory_xact_lock_shared</primary>
29082 </indexterm>
29083 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
29084 <returnvalue>boolean</returnvalue>
29085 </para>
29086 <para role="func_signature">
29087 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
29088 <returnvalue>boolean</returnvalue>
29089 </para>
29090 <para>
29091 Obtains a shared transaction-level advisory lock if available.
29092 This will either obtain the lock immediately and
29093 return <literal>true</literal>, or return <literal>false</literal>
29094 without waiting if the lock cannot be acquired immediately.
29095 </para></entry>
29096 </row>
29097 </tbody>
29098 </tgroup>
29099 </table>
29101 </sect2>
29103 </sect1>
29105 <sect1 id="functions-trigger">
29106 <title>Trigger Functions</title>
29108 <para>
29109 While many uses of triggers involve user-written trigger functions,
29110 <productname>PostgreSQL</productname> provides a few built-in trigger
29111 functions that can be used directly in user-defined triggers. These
29112 are summarized in <xref linkend="builtin-triggers-table"/>.
29113 (Additional built-in trigger functions exist, which implement foreign
29114 key constraints and deferred index constraints. Those are not documented
29115 here since users need not use them directly.)
29116 </para>
29118 <para>
29119 For more information about creating triggers, see
29120 <xref linkend="sql-createtrigger"/>.
29121 </para>
29123 <table id="builtin-triggers-table">
29124 <title>Built-In Trigger Functions</title>
29125 <tgroup cols="1">
29126 <thead>
29127 <row>
29128 <entry role="func_table_entry"><para role="func_signature">
29129 Function
29130 </para>
29131 <para>
29132 Description
29133 </para>
29134 <para>
29135 Example Usage
29136 </para></entry>
29137 </row>
29138 </thead>
29140 <tbody>
29141 <row>
29142 <entry role="func_table_entry"><para role="func_signature">
29143 <indexterm>
29144 <primary>suppress_redundant_updates_trigger</primary>
29145 </indexterm>
29146 <function>suppress_redundant_updates_trigger</function> ( )
29147 <returnvalue>trigger</returnvalue>
29148 </para>
29149 <para>
29150 Suppresses do-nothing update operations. See below for details.
29151 </para>
29152 <para>
29153 <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()</literal>
29154 </para></entry>
29155 </row>
29157 <row>
29158 <entry role="func_table_entry"><para role="func_signature">
29159 <indexterm>
29160 <primary>tsvector_update_trigger</primary>
29161 </indexterm>
29162 <function>tsvector_update_trigger</function> ( )
29163 <returnvalue>trigger</returnvalue>
29164 </para>
29165 <para>
29166 Automatically updates a <type>tsvector</type> column from associated
29167 plain-text document column(s). The text search configuration to use
29168 is specified by name as a trigger argument. See
29169 <xref linkend="textsearch-update-triggers"/> for details.
29170 </para>
29171 <para>
29172 <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal>
29173 </para></entry>
29174 </row>
29176 <row>
29177 <entry role="func_table_entry"><para role="func_signature">
29178 <indexterm>
29179 <primary>tsvector_update_trigger_column</primary>
29180 </indexterm>
29181 <function>tsvector_update_trigger_column</function> ( )
29182 <returnvalue>trigger</returnvalue>
29183 </para>
29184 <para>
29185 Automatically updates a <type>tsvector</type> column from associated
29186 plain-text document column(s). The text search configuration to use
29187 is taken from a <type>regconfig</type> column of the table. See
29188 <xref linkend="textsearch-update-triggers"/> for details.
29189 </para>
29190 <para>
29191 <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)</literal>
29192 </para></entry>
29193 </row>
29194 </tbody>
29195 </tgroup>
29196 </table>
29198 <para>
29199 The <function>suppress_redundant_updates_trigger</function> function,
29200 when applied as a row-level <literal>BEFORE UPDATE</literal> trigger,
29201 will prevent any update that does not actually change the data in the
29202 row from taking place. This overrides the normal behavior which always
29203 performs a physical row update
29204 regardless of whether or not the data has changed. (This normal behavior
29205 makes updates run faster, since no checking is required, and is also
29206 useful in certain cases.)
29207 </para>
29209 <para>
29210 Ideally, you should avoid running updates that don't actually
29211 change the data in the record. Redundant updates can cost considerable
29212 unnecessary time, especially if there are lots of indexes to alter,
29213 and space in dead rows that will eventually have to be vacuumed.
29214 However, detecting such situations in client code is not
29215 always easy, or even possible, and writing expressions to detect
29216 them can be error-prone. An alternative is to use
29217 <function>suppress_redundant_updates_trigger</function>, which will skip
29218 updates that don't change the data. You should use this with care,
29219 however. The trigger takes a small but non-trivial time for each record,
29220 so if most of the records affected by updates do actually change,
29221 use of this trigger will make updates run slower on average.
29222 </para>
29224 <para>
29225 The <function>suppress_redundant_updates_trigger</function> function can be
29226 added to a table like this:
29227 <programlisting>
29228 CREATE TRIGGER z_min_update
29229 BEFORE UPDATE ON tablename
29230 FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger();
29231 </programlisting>
29232 In most cases, you need to fire this trigger last for each row, so that
29233 it does not override other triggers that might wish to alter the row.
29234 Bearing in mind that triggers fire in name order, you would therefore
29235 choose a trigger name that comes after the name of any other trigger
29236 you might have on the table. (Hence the <quote>z</quote> prefix in the
29237 example.)
29238 </para>
29239 </sect1>
29241 <sect1 id="functions-event-triggers">
29242 <title>Event Trigger Functions</title>
29244 <para>
29245 <productname>PostgreSQL</productname> provides these helper functions
29246 to retrieve information from event triggers.
29247 </para>
29249 <para>
29250 For more information about event triggers,
29251 see <xref linkend="event-triggers"/>.
29252 </para>
29254 <sect2 id="pg-event-trigger-ddl-command-end-functions">
29255 <title>Capturing Changes at Command End</title>
29257 <indexterm>
29258 <primary>pg_event_trigger_ddl_commands</primary>
29259 </indexterm>
29261 <synopsis>
29262 <function>pg_event_trigger_ddl_commands</function> () <returnvalue>setof record</returnvalue>
29263 </synopsis>
29265 <para>
29266 <function>pg_event_trigger_ddl_commands</function> returns a list of
29267 <acronym>DDL</acronym> commands executed by each user action,
29268 when invoked in a function attached to a
29269 <literal>ddl_command_end</literal> event trigger. If called in any other
29270 context, an error is raised.
29271 <function>pg_event_trigger_ddl_commands</function> returns one row for each
29272 base command executed; some commands that are a single SQL sentence
29273 may return more than one row. This function returns the following
29274 columns:
29276 <informaltable>
29277 <tgroup cols="3">
29278 <thead>
29279 <row>
29280 <entry>Name</entry>
29281 <entry>Type</entry>
29282 <entry>Description</entry>
29283 </row>
29284 </thead>
29286 <tbody>
29287 <row>
29288 <entry><literal>classid</literal></entry>
29289 <entry><type>oid</type></entry>
29290 <entry>OID of catalog the object belongs in</entry>
29291 </row>
29292 <row>
29293 <entry><literal>objid</literal></entry>
29294 <entry><type>oid</type></entry>
29295 <entry>OID of the object itself</entry>
29296 </row>
29297 <row>
29298 <entry><literal>objsubid</literal></entry>
29299 <entry><type>integer</type></entry>
29300 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
29301 </row>
29302 <row>
29303 <entry><literal>command_tag</literal></entry>
29304 <entry><type>text</type></entry>
29305 <entry>Command tag</entry>
29306 </row>
29307 <row>
29308 <entry><literal>object_type</literal></entry>
29309 <entry><type>text</type></entry>
29310 <entry>Type of the object</entry>
29311 </row>
29312 <row>
29313 <entry><literal>schema_name</literal></entry>
29314 <entry><type>text</type></entry>
29315 <entry>
29316 Name of the schema the object belongs in, if any; otherwise <literal>NULL</literal>.
29317 No quoting is applied.
29318 </entry>
29319 </row>
29320 <row>
29321 <entry><literal>object_identity</literal></entry>
29322 <entry><type>text</type></entry>
29323 <entry>
29324 Text rendering of the object identity, schema-qualified. Each
29325 identifier included in the identity is quoted if necessary.
29326 </entry>
29327 </row>
29328 <row>
29329 <entry><literal>in_extension</literal></entry>
29330 <entry><type>boolean</type></entry>
29331 <entry>True if the command is part of an extension script</entry>
29332 </row>
29333 <row>
29334 <entry><literal>command</literal></entry>
29335 <entry><type>pg_ddl_command</type></entry>
29336 <entry>
29337 A complete representation of the command, in internal format.
29338 This cannot be output directly, but it can be passed to other
29339 functions to obtain different pieces of information about the
29340 command.
29341 </entry>
29342 </row>
29343 </tbody>
29344 </tgroup>
29345 </informaltable>
29346 </para>
29347 </sect2>
29349 <sect2 id="pg-event-trigger-sql-drop-functions">
29350 <title>Processing Objects Dropped by a DDL Command</title>
29352 <indexterm>
29353 <primary>pg_event_trigger_dropped_objects</primary>
29354 </indexterm>
29356 <synopsis>
29357 <function>pg_event_trigger_dropped_objects</function> () <returnvalue>setof record</returnvalue>
29358 </synopsis>
29360 <para>
29361 <function>pg_event_trigger_dropped_objects</function> returns a list of all objects
29362 dropped by the command in whose <literal>sql_drop</literal> event it is called.
29363 If called in any other context, an error is raised.
29364 This function returns the following columns:
29366 <informaltable>
29367 <tgroup cols="3">
29368 <thead>
29369 <row>
29370 <entry>Name</entry>
29371 <entry>Type</entry>
29372 <entry>Description</entry>
29373 </row>
29374 </thead>
29376 <tbody>
29377 <row>
29378 <entry><literal>classid</literal></entry>
29379 <entry><type>oid</type></entry>
29380 <entry>OID of catalog the object belonged in</entry>
29381 </row>
29382 <row>
29383 <entry><literal>objid</literal></entry>
29384 <entry><type>oid</type></entry>
29385 <entry>OID of the object itself</entry>
29386 </row>
29387 <row>
29388 <entry><literal>objsubid</literal></entry>
29389 <entry><type>integer</type></entry>
29390 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
29391 </row>
29392 <row>
29393 <entry><literal>original</literal></entry>
29394 <entry><type>boolean</type></entry>
29395 <entry>True if this was one of the root object(s) of the deletion</entry>
29396 </row>
29397 <row>
29398 <entry><literal>normal</literal></entry>
29399 <entry><type>boolean</type></entry>
29400 <entry>
29401 True if there was a normal dependency relationship
29402 in the dependency graph leading to this object
29403 </entry>
29404 </row>
29405 <row>
29406 <entry><literal>is_temporary</literal></entry>
29407 <entry><type>boolean</type></entry>
29408 <entry>
29409 True if this was a temporary object
29410 </entry>
29411 </row>
29412 <row>
29413 <entry><literal>object_type</literal></entry>
29414 <entry><type>text</type></entry>
29415 <entry>Type of the object</entry>
29416 </row>
29417 <row>
29418 <entry><literal>schema_name</literal></entry>
29419 <entry><type>text</type></entry>
29420 <entry>
29421 Name of the schema the object belonged in, if any; otherwise <literal>NULL</literal>.
29422 No quoting is applied.
29423 </entry>
29424 </row>
29425 <row>
29426 <entry><literal>object_name</literal></entry>
29427 <entry><type>text</type></entry>
29428 <entry>
29429 Name of the object, if the combination of schema and name can be
29430 used as a unique identifier for the object; otherwise <literal>NULL</literal>.
29431 No quoting is applied, and name is never schema-qualified.
29432 </entry>
29433 </row>
29434 <row>
29435 <entry><literal>object_identity</literal></entry>
29436 <entry><type>text</type></entry>
29437 <entry>
29438 Text rendering of the object identity, schema-qualified. Each
29439 identifier included in the identity is quoted if necessary.
29440 </entry>
29441 </row>
29442 <row>
29443 <entry><literal>address_names</literal></entry>
29444 <entry><type>text[]</type></entry>
29445 <entry>
29446 An array that, together with <literal>object_type</literal> and
29447 <literal>address_args</literal>, can be used by
29448 the <function>pg_get_object_address</function> function to
29449 recreate the object address in a remote server containing an
29450 identically named object of the same kind.
29451 </entry>
29452 </row>
29453 <row>
29454 <entry><literal>address_args</literal></entry>
29455 <entry><type>text[]</type></entry>
29456 <entry>
29457 Complement for <literal>address_names</literal>
29458 </entry>
29459 </row>
29460 </tbody>
29461 </tgroup>
29462 </informaltable>
29463 </para>
29465 <para>
29466 The <function>pg_event_trigger_dropped_objects</function> function can be used
29467 in an event trigger like this:
29468 <programlisting>
29469 CREATE FUNCTION test_event_trigger_for_drops()
29470 RETURNS event_trigger LANGUAGE plpgsql AS $$
29471 DECLARE
29472 obj record;
29473 BEGIN
29474 FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
29475 LOOP
29476 RAISE NOTICE '% dropped object: % %.% %',
29477 tg_tag,
29478 obj.object_type,
29479 obj.schema_name,
29480 obj.object_name,
29481 obj.object_identity;
29482 END LOOP;
29483 END;
29485 CREATE EVENT TRIGGER test_event_trigger_for_drops
29486 ON sql_drop
29487 EXECUTE FUNCTION test_event_trigger_for_drops();
29488 </programlisting>
29489 </para>
29490 </sect2>
29492 <sect2 id="pg-event-trigger-table-rewrite-functions">
29493 <title>Handling a Table Rewrite Event</title>
29495 <para>
29496 The functions shown in
29497 <xref linkend="functions-event-trigger-table-rewrite"/>
29498 provide information about a table for which a
29499 <literal>table_rewrite</literal> event has just been called.
29500 If called in any other context, an error is raised.
29501 </para>
29503 <table id="functions-event-trigger-table-rewrite">
29504 <title>Table Rewrite Information Functions</title>
29505 <tgroup cols="1">
29506 <thead>
29507 <row>
29508 <entry role="func_table_entry"><para role="func_signature">
29509 Function
29510 </para>
29511 <para>
29512 Description
29513 </para></entry>
29514 </row>
29515 </thead>
29517 <tbody>
29518 <row>
29519 <entry role="func_table_entry"><para role="func_signature">
29520 <indexterm>
29521 <primary>pg_event_trigger_table_rewrite_oid</primary>
29522 </indexterm>
29523 <function>pg_event_trigger_table_rewrite_oid</function> ()
29524 <returnvalue>oid</returnvalue>
29525 </para>
29526 <para>
29527 Returns the OID of the table about to be rewritten.
29528 </para></entry>
29529 </row>
29531 <row>
29532 <entry role="func_table_entry"><para role="func_signature">
29533 <indexterm>
29534 <primary>pg_event_trigger_table_rewrite_reason</primary>
29535 </indexterm>
29536 <function>pg_event_trigger_table_rewrite_reason</function> ()
29537 <returnvalue>integer</returnvalue>
29538 </para>
29539 <para>
29540 Returns a code explaining the reason(s) for rewriting. The exact
29541 meaning of the codes is release dependent.
29542 </para></entry>
29543 </row>
29544 </tbody>
29545 </tgroup>
29546 </table>
29548 <para>
29549 These functions can be used in an event trigger like this:
29550 <programlisting>
29551 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
29552 RETURNS event_trigger
29553 LANGUAGE plpgsql AS
29555 BEGIN
29556 RAISE NOTICE 'rewriting table % for reason %',
29557 pg_event_trigger_table_rewrite_oid()::regclass,
29558 pg_event_trigger_table_rewrite_reason();
29559 END;
29562 CREATE EVENT TRIGGER test_table_rewrite_oid
29563 ON table_rewrite
29564 EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
29565 </programlisting>
29566 </para>
29567 </sect2>
29568 </sect1>
29570 <sect1 id="functions-statistics">
29571 <title>Statistics Information Functions</title>
29573 <indexterm zone="functions-statistics">
29574 <primary>function</primary>
29575 <secondary>statistics</secondary>
29576 </indexterm>
29578 <para>
29579 <productname>PostgreSQL</productname> provides a function to inspect complex
29580 statistics defined using the <command>CREATE STATISTICS</command> command.
29581 </para>
29583 <sect2 id="functions-statistics-mcv">
29584 <title>Inspecting MCV Lists</title>
29586 <indexterm>
29587 <primary>pg_mcv_list_items</primary>
29588 </indexterm>
29590 <synopsis>
29591 <function>pg_mcv_list_items</function> ( <type>pg_mcv_list</type> ) <returnvalue>setof record</returnvalue>
29592 </synopsis>
29594 <para>
29595 <function>pg_mcv_list_items</function> returns a set of records describing
29596 all items stored in a multi-column <acronym>MCV</acronym> list. It
29597 returns the following columns:
29599 <informaltable>
29600 <tgroup cols="3">
29601 <thead>
29602 <row>
29603 <entry>Name</entry>
29604 <entry>Type</entry>
29605 <entry>Description</entry>
29606 </row>
29607 </thead>
29609 <tbody>
29610 <row>
29611 <entry><literal>index</literal></entry>
29612 <entry><type>integer</type></entry>
29613 <entry>index of the item in the <acronym>MCV</acronym> list</entry>
29614 </row>
29615 <row>
29616 <entry><literal>values</literal></entry>
29617 <entry><type>text[]</type></entry>
29618 <entry>values stored in the MCV item</entry>
29619 </row>
29620 <row>
29621 <entry><literal>nulls</literal></entry>
29622 <entry><type>boolean[]</type></entry>
29623 <entry>flags identifying <literal>NULL</literal> values</entry>
29624 </row>
29625 <row>
29626 <entry><literal>frequency</literal></entry>
29627 <entry><type>double precision</type></entry>
29628 <entry>frequency of this <acronym>MCV</acronym> item</entry>
29629 </row>
29630 <row>
29631 <entry><literal>base_frequency</literal></entry>
29632 <entry><type>double precision</type></entry>
29633 <entry>base frequency of this <acronym>MCV</acronym> item</entry>
29634 </row>
29635 </tbody>
29636 </tgroup>
29637 </informaltable>
29638 </para>
29640 <para>
29641 The <function>pg_mcv_list_items</function> function can be used like this:
29643 <programlisting>
29644 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
29645 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
29646 </programlisting>
29648 Values of the <type>pg_mcv_list</type> type can be obtained only from the
29649 <structname>pg_statistic_ext_data</structname>.<structfield>stxdmcv</structfield>
29650 column.
29651 </para>
29652 </sect2>
29654 </sect1>
29656 </chapter>