Repair memory leaks in plpython.
[pgsql.git] / doc / src / sgml / func.sgml
blob47370e581aef778c2878afdf7ceffc7daa0f0714
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</primary>
1869 </indexterm>
1870 <function>random</function> ( <parameter>min</parameter> <type>integer</type>, <parameter>max</parameter> <type>integer</type> )
1871 <returnvalue>integer</returnvalue>
1872 </para>
1873 <para role="func_signature">
1874 <function>random</function> ( <parameter>min</parameter> <type>bigint</type>, <parameter>max</parameter> <type>bigint</type> )
1875 <returnvalue>bigint</returnvalue>
1876 </para>
1877 <para role="func_signature">
1878 <function>random</function> ( <parameter>min</parameter> <type>numeric</type>, <parameter>max</parameter> <type>numeric</type> )
1879 <returnvalue>numeric</returnvalue>
1880 </para>
1881 <para>
1882 Returns a random value in the range
1883 <parameter>min</parameter> &lt;= x &lt;= <parameter>max</parameter>.
1884 For type <type>numeric</type>, the result will have the same number of
1885 fractional decimal digits as <parameter>min</parameter> or
1886 <parameter>max</parameter>, whichever has more.
1887 </para>
1888 <para>
1889 <literal>random(1, 10)</literal>
1890 <returnvalue>7</returnvalue>
1891 </para>
1892 <para>
1893 <literal>random(-0.499, 0.499)</literal>
1894 <returnvalue>0.347</returnvalue>
1895 </para></entry>
1896 </row>
1898 <row>
1899 <entry role="func_table_entry"><para role="func_signature">
1900 <indexterm>
1901 <primary>random_normal</primary>
1902 </indexterm>
1904 <function>random_normal</function> (
1905 <optional> <parameter>mean</parameter> <type>double precision</type>
1906 <optional>, <parameter>stddev</parameter> <type>double precision</type> </optional></optional> )
1907 <returnvalue>double precision</returnvalue>
1908 </para>
1909 <para>
1910 Returns a random value from the normal distribution with the given
1911 parameters; <parameter>mean</parameter> defaults to 0.0
1912 and <parameter>stddev</parameter> defaults to 1.0
1913 </para>
1914 <para>
1915 <literal>random_normal(0.0, 1.0)</literal>
1916 <returnvalue>0.051285419</returnvalue>
1917 </para></entry>
1918 </row>
1920 <row>
1921 <entry role="func_table_entry"><para role="func_signature">
1922 <indexterm>
1923 <primary>setseed</primary>
1924 </indexterm>
1925 <function>setseed</function> ( <type>double precision</type> )
1926 <returnvalue>void</returnvalue>
1927 </para>
1928 <para>
1929 Sets the seed for subsequent <literal>random()</literal> and
1930 <literal>random_normal()</literal> calls;
1931 argument must be between -1.0 and 1.0, inclusive
1932 </para>
1933 <para>
1934 <literal>setseed(0.12345)</literal>
1935 </para></entry>
1936 </row>
1937 </tbody>
1938 </tgroup>
1939 </table>
1941 <para>
1942 The <function>random()</function> and <function>random_normal()</function>
1943 functions listed in <xref linkend="functions-math-random-table"/> use a
1944 deterministic pseudo-random number generator.
1945 It is fast but not suitable for cryptographic
1946 applications; see the <xref linkend="pgcrypto"/> module for a more
1947 secure alternative.
1948 If <function>setseed()</function> is called, the series of results of
1949 subsequent calls to these functions in the current session
1950 can be repeated by re-issuing <function>setseed()</function> with the same
1951 argument.
1952 Without any prior <function>setseed()</function> call in the same
1953 session, the first call to any of these functions obtains a seed
1954 from a platform-dependent source of random bits.
1955 </para>
1957 <para>
1958 <xref linkend="functions-math-trig-table"/> shows the
1959 available trigonometric functions. Each of these functions comes in
1960 two variants, one that measures angles in radians and one that
1961 measures angles in degrees.
1962 </para>
1964 <table id="functions-math-trig-table">
1965 <title>Trigonometric Functions</title>
1967 <tgroup cols="1">
1968 <thead>
1969 <row>
1970 <entry role="func_table_entry"><para role="func_signature">
1971 Function
1972 </para>
1973 <para>
1974 Description
1975 </para>
1976 <para>
1977 Example(s)
1978 </para></entry>
1979 </row>
1980 </thead>
1982 <tbody>
1983 <row>
1984 <entry role="func_table_entry"><para role="func_signature">
1985 <indexterm>
1986 <primary>acos</primary>
1987 </indexterm>
1988 <function>acos</function> ( <type>double precision</type> )
1989 <returnvalue>double precision</returnvalue>
1990 </para>
1991 <para>
1992 Inverse cosine, result in radians
1993 </para>
1994 <para>
1995 <literal>acos(1)</literal>
1996 <returnvalue>0</returnvalue>
1997 </para></entry>
1998 </row>
2000 <row>
2001 <entry role="func_table_entry"><para role="func_signature">
2002 <indexterm>
2003 <primary>acosd</primary>
2004 </indexterm>
2005 <function>acosd</function> ( <type>double precision</type> )
2006 <returnvalue>double precision</returnvalue>
2007 </para>
2008 <para>
2009 Inverse cosine, result in degrees
2010 </para>
2011 <para>
2012 <literal>acosd(0.5)</literal>
2013 <returnvalue>60</returnvalue>
2014 </para></entry>
2015 </row>
2017 <row>
2018 <entry role="func_table_entry"><para role="func_signature">
2019 <indexterm>
2020 <primary>asin</primary>
2021 </indexterm>
2022 <function>asin</function> ( <type>double precision</type> )
2023 <returnvalue>double precision</returnvalue>
2024 </para>
2025 <para>
2026 Inverse sine, result in radians
2027 </para>
2028 <para>
2029 <literal>asin(1)</literal>
2030 <returnvalue>1.5707963267948966</returnvalue>
2031 </para></entry>
2032 </row>
2034 <row>
2035 <entry role="func_table_entry"><para role="func_signature">
2036 <indexterm>
2037 <primary>asind</primary>
2038 </indexterm>
2039 <function>asind</function> ( <type>double precision</type> )
2040 <returnvalue>double precision</returnvalue>
2041 </para>
2042 <para>
2043 Inverse sine, result in degrees
2044 </para>
2045 <para>
2046 <literal>asind(0.5)</literal>
2047 <returnvalue>30</returnvalue>
2048 </para></entry>
2049 </row>
2051 <row>
2052 <entry role="func_table_entry"><para role="func_signature">
2053 <indexterm>
2054 <primary>atan</primary>
2055 </indexterm>
2056 <function>atan</function> ( <type>double precision</type> )
2057 <returnvalue>double precision</returnvalue>
2058 </para>
2059 <para>
2060 Inverse tangent, result in radians
2061 </para>
2062 <para>
2063 <literal>atan(1)</literal>
2064 <returnvalue>0.7853981633974483</returnvalue>
2065 </para></entry>
2066 </row>
2068 <row>
2069 <entry role="func_table_entry"><para role="func_signature">
2070 <indexterm>
2071 <primary>atand</primary>
2072 </indexterm>
2073 <function>atand</function> ( <type>double precision</type> )
2074 <returnvalue>double precision</returnvalue>
2075 </para>
2076 <para>
2077 Inverse tangent, result in degrees
2078 </para>
2079 <para>
2080 <literal>atand(1)</literal>
2081 <returnvalue>45</returnvalue>
2082 </para></entry>
2083 </row>
2085 <row>
2086 <entry role="func_table_entry"><para role="func_signature">
2087 <indexterm>
2088 <primary>atan2</primary>
2089 </indexterm>
2090 <function>atan2</function> ( <parameter>y</parameter> <type>double precision</type>,
2091 <parameter>x</parameter> <type>double precision</type> )
2092 <returnvalue>double precision</returnvalue>
2093 </para>
2094 <para>
2095 Inverse tangent of
2096 <parameter>y</parameter>/<parameter>x</parameter>,
2097 result in radians
2098 </para>
2099 <para>
2100 <literal>atan2(1, 0)</literal>
2101 <returnvalue>1.5707963267948966</returnvalue>
2102 </para></entry>
2103 </row>
2105 <row>
2106 <entry role="func_table_entry"><para role="func_signature">
2107 <indexterm>
2108 <primary>atan2d</primary>
2109 </indexterm>
2110 <function>atan2d</function> ( <parameter>y</parameter> <type>double precision</type>,
2111 <parameter>x</parameter> <type>double precision</type> )
2112 <returnvalue>double precision</returnvalue>
2113 </para>
2114 <para>
2115 Inverse tangent of
2116 <parameter>y</parameter>/<parameter>x</parameter>,
2117 result in degrees
2118 </para>
2119 <para>
2120 <literal>atan2d(1, 0)</literal>
2121 <returnvalue>90</returnvalue>
2122 </para></entry>
2123 </row>
2125 <row>
2126 <entry role="func_table_entry"><para role="func_signature">
2127 <indexterm>
2128 <primary>cos</primary>
2129 </indexterm>
2130 <function>cos</function> ( <type>double precision</type> )
2131 <returnvalue>double precision</returnvalue>
2132 </para>
2133 <para>
2134 Cosine, argument in radians
2135 </para>
2136 <para>
2137 <literal>cos(0)</literal>
2138 <returnvalue>1</returnvalue>
2139 </para></entry>
2140 </row>
2142 <row>
2143 <entry role="func_table_entry"><para role="func_signature">
2144 <indexterm>
2145 <primary>cosd</primary>
2146 </indexterm>
2147 <function>cosd</function> ( <type>double precision</type> )
2148 <returnvalue>double precision</returnvalue>
2149 </para>
2150 <para>
2151 Cosine, argument in degrees
2152 </para>
2153 <para>
2154 <literal>cosd(60)</literal>
2155 <returnvalue>0.5</returnvalue>
2156 </para></entry>
2157 </row>
2159 <row>
2160 <entry role="func_table_entry"><para role="func_signature">
2161 <indexterm>
2162 <primary>cot</primary>
2163 </indexterm>
2164 <function>cot</function> ( <type>double precision</type> )
2165 <returnvalue>double precision</returnvalue>
2166 </para>
2167 <para>
2168 Cotangent, argument in radians
2169 </para>
2170 <para>
2171 <literal>cot(0.5)</literal>
2172 <returnvalue>1.830487721712452</returnvalue>
2173 </para></entry>
2174 </row>
2176 <row>
2177 <entry role="func_table_entry"><para role="func_signature">
2178 <indexterm>
2179 <primary>cotd</primary>
2180 </indexterm>
2181 <function>cotd</function> ( <type>double precision</type> )
2182 <returnvalue>double precision</returnvalue>
2183 </para>
2184 <para>
2185 Cotangent, argument in degrees
2186 </para>
2187 <para>
2188 <literal>cotd(45)</literal>
2189 <returnvalue>1</returnvalue>
2190 </para></entry>
2191 </row>
2193 <row>
2194 <entry role="func_table_entry"><para role="func_signature">
2195 <indexterm>
2196 <primary>sin</primary>
2197 </indexterm>
2198 <function>sin</function> ( <type>double precision</type> )
2199 <returnvalue>double precision</returnvalue>
2200 </para>
2201 <para>
2202 Sine, argument in radians
2203 </para>
2204 <para>
2205 <literal>sin(1)</literal>
2206 <returnvalue>0.8414709848078965</returnvalue>
2207 </para></entry>
2208 </row>
2210 <row>
2211 <entry role="func_table_entry"><para role="func_signature">
2212 <indexterm>
2213 <primary>sind</primary>
2214 </indexterm>
2215 <function>sind</function> ( <type>double precision</type> )
2216 <returnvalue>double precision</returnvalue>
2217 </para>
2218 <para>
2219 Sine, argument in degrees
2220 </para>
2221 <para>
2222 <literal>sind(30)</literal>
2223 <returnvalue>0.5</returnvalue>
2224 </para></entry>
2225 </row>
2227 <row>
2228 <entry role="func_table_entry"><para role="func_signature">
2229 <indexterm>
2230 <primary>tan</primary>
2231 </indexterm>
2232 <function>tan</function> ( <type>double precision</type> )
2233 <returnvalue>double precision</returnvalue>
2234 </para>
2235 <para>
2236 Tangent, argument in radians
2237 </para>
2238 <para>
2239 <literal>tan(1)</literal>
2240 <returnvalue>1.5574077246549023</returnvalue>
2241 </para></entry>
2242 </row>
2244 <row>
2245 <entry role="func_table_entry"><para role="func_signature">
2246 <indexterm>
2247 <primary>tand</primary>
2248 </indexterm>
2249 <function>tand</function> ( <type>double precision</type> )
2250 <returnvalue>double precision</returnvalue>
2251 </para>
2252 <para>
2253 Tangent, argument in degrees
2254 </para>
2255 <para>
2256 <literal>tand(45)</literal>
2257 <returnvalue>1</returnvalue>
2258 </para></entry>
2259 </row>
2260 </tbody>
2261 </tgroup>
2262 </table>
2264 <note>
2265 <para>
2266 Another way to work with angles measured in degrees is to use the unit
2267 transformation functions <literal><function>radians()</function></literal>
2268 and <literal><function>degrees()</function></literal> shown earlier.
2269 However, using the degree-based trigonometric functions is preferred,
2270 as that way avoids round-off error for special cases such
2271 as <literal>sind(30)</literal>.
2272 </para>
2273 </note>
2275 <para>
2276 <xref linkend="functions-math-hyp-table"/> shows the
2277 available hyperbolic functions.
2278 </para>
2280 <table id="functions-math-hyp-table">
2281 <title>Hyperbolic Functions</title>
2283 <tgroup cols="1">
2284 <thead>
2285 <row>
2286 <entry role="func_table_entry"><para role="func_signature">
2287 Function
2288 </para>
2289 <para>
2290 Description
2291 </para>
2292 <para>
2293 Example(s)
2294 </para></entry>
2295 </row>
2296 </thead>
2298 <tbody>
2299 <row>
2300 <entry role="func_table_entry"><para role="func_signature">
2301 <indexterm>
2302 <primary>sinh</primary>
2303 </indexterm>
2304 <function>sinh</function> ( <type>double precision</type> )
2305 <returnvalue>double precision</returnvalue>
2306 </para>
2307 <para>
2308 Hyperbolic sine
2309 </para>
2310 <para>
2311 <literal>sinh(1)</literal>
2312 <returnvalue>1.1752011936438014</returnvalue>
2313 </para></entry>
2314 </row>
2316 <row>
2317 <entry role="func_table_entry"><para role="func_signature">
2318 <indexterm>
2319 <primary>cosh</primary>
2320 </indexterm>
2321 <function>cosh</function> ( <type>double precision</type> )
2322 <returnvalue>double precision</returnvalue>
2323 </para>
2324 <para>
2325 Hyperbolic cosine
2326 </para>
2327 <para>
2328 <literal>cosh(0)</literal>
2329 <returnvalue>1</returnvalue>
2330 </para></entry>
2331 </row>
2333 <row>
2334 <entry role="func_table_entry"><para role="func_signature">
2335 <indexterm>
2336 <primary>tanh</primary>
2337 </indexterm>
2338 <function>tanh</function> ( <type>double precision</type> )
2339 <returnvalue>double precision</returnvalue>
2340 </para>
2341 <para>
2342 Hyperbolic tangent
2343 </para>
2344 <para>
2345 <literal>tanh(1)</literal>
2346 <returnvalue>0.7615941559557649</returnvalue>
2347 </para></entry>
2348 </row>
2350 <row>
2351 <entry role="func_table_entry"><para role="func_signature">
2352 <indexterm>
2353 <primary>asinh</primary>
2354 </indexterm>
2355 <function>asinh</function> ( <type>double precision</type> )
2356 <returnvalue>double precision</returnvalue>
2357 </para>
2358 <para>
2359 Inverse hyperbolic sine
2360 </para>
2361 <para>
2362 <literal>asinh(1)</literal>
2363 <returnvalue>0.881373587019543</returnvalue>
2364 </para></entry>
2365 </row>
2367 <row>
2368 <entry role="func_table_entry"><para role="func_signature">
2369 <indexterm>
2370 <primary>acosh</primary>
2371 </indexterm>
2372 <function>acosh</function> ( <type>double precision</type> )
2373 <returnvalue>double precision</returnvalue>
2374 </para>
2375 <para>
2376 Inverse hyperbolic cosine
2377 </para>
2378 <para>
2379 <literal>acosh(1)</literal>
2380 <returnvalue>0</returnvalue>
2381 </para></entry>
2382 </row>
2384 <row>
2385 <entry role="func_table_entry"><para role="func_signature">
2386 <indexterm>
2387 <primary>atanh</primary>
2388 </indexterm>
2389 <function>atanh</function> ( <type>double precision</type> )
2390 <returnvalue>double precision</returnvalue>
2391 </para>
2392 <para>
2393 Inverse hyperbolic tangent
2394 </para>
2395 <para>
2396 <literal>atanh(0.5)</literal>
2397 <returnvalue>0.5493061443340548</returnvalue>
2398 </para></entry>
2399 </row>
2400 </tbody>
2401 </tgroup>
2402 </table>
2404 </sect1>
2407 <sect1 id="functions-string">
2408 <title>String Functions and Operators</title>
2410 <para>
2411 This section describes functions and operators for examining and
2412 manipulating string values. Strings in this context include values
2413 of the types <type>character</type>, <type>character varying</type>,
2414 and <type>text</type>. Except where noted, these functions and operators
2415 are declared to accept and return type <type>text</type>. They will
2416 interchangeably accept <type>character varying</type> arguments.
2417 Values of type <type>character</type> will be converted
2418 to <type>text</type> before the function or operator is applied, resulting
2419 in stripping any trailing spaces in the <type>character</type> value.
2420 </para>
2422 <para>
2423 <acronym>SQL</acronym> defines some string functions that use
2424 key words, rather than commas, to separate
2425 arguments. Details are in
2426 <xref linkend="functions-string-sql"/>.
2427 <productname>PostgreSQL</productname> also provides versions of these functions
2428 that use the regular function invocation syntax
2429 (see <xref linkend="functions-string-other"/>).
2430 </para>
2432 <note>
2433 <para>
2434 The string concatenation operator (<literal>||</literal>) will accept
2435 non-string input, so long as at least one input is of string type, as shown
2436 in <xref linkend="functions-string-sql"/>. For other cases, inserting an
2437 explicit coercion to <type>text</type> can be used to have non-string input
2438 accepted.
2439 </para>
2440 </note>
2442 <table id="functions-string-sql">
2443 <title><acronym>SQL</acronym> String Functions and Operators</title>
2444 <tgroup cols="1">
2445 <thead>
2446 <row>
2447 <entry role="func_table_entry"><para role="func_signature">
2448 Function/Operator
2449 </para>
2450 <para>
2451 Description
2452 </para>
2453 <para>
2454 Example(s)
2455 </para></entry>
2456 </row>
2457 </thead>
2459 <tbody>
2460 <row>
2461 <entry role="func_table_entry"><para role="func_signature">
2462 <indexterm>
2463 <primary>character string</primary>
2464 <secondary>concatenation</secondary>
2465 </indexterm>
2466 <type>text</type> <literal>||</literal> <type>text</type>
2467 <returnvalue>text</returnvalue>
2468 </para>
2469 <para>
2470 Concatenates the two strings.
2471 </para>
2472 <para>
2473 <literal>'Post' || 'greSQL'</literal>
2474 <returnvalue>PostgreSQL</returnvalue>
2475 </para></entry>
2476 </row>
2478 <row>
2479 <entry role="func_table_entry"><para role="func_signature">
2480 <type>text</type> <literal>||</literal> <type>anynonarray</type>
2481 <returnvalue>text</returnvalue>
2482 </para>
2483 <para role="func_signature">
2484 <type>anynonarray</type> <literal>||</literal> <type>text</type>
2485 <returnvalue>text</returnvalue>
2486 </para>
2487 <para>
2488 Converts the non-string input to text, then concatenates the two
2489 strings. (The non-string input cannot be of an array type, because
2490 that would create ambiguity with the array <literal>||</literal>
2491 operators. If you want to concatenate an array's text equivalent,
2492 cast it to <type>text</type> explicitly.)
2493 </para>
2494 <para>
2495 <literal>'Value: ' || 42</literal>
2496 <returnvalue>Value: 42</returnvalue>
2497 </para></entry>
2498 </row>
2500 <row>
2501 <entry role="func_table_entry"><para role="func_signature">
2502 <indexterm>
2503 <primary>btrim</primary>
2504 </indexterm>
2505 <function>btrim</function> ( <parameter>string</parameter> <type>text</type>
2506 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2507 <returnvalue>text</returnvalue>
2508 </para>
2509 <para>
2510 Removes the longest string containing only characters
2511 in <parameter>characters</parameter> (a space by default)
2512 from the start and end of <parameter>string</parameter>.
2513 </para>
2514 <para>
2515 <literal>btrim('xyxtrimyyx', 'xyz')</literal>
2516 <returnvalue>trim</returnvalue>
2517 </para></entry>
2518 </row>
2520 <row>
2521 <entry role="func_table_entry"><para role="func_signature">
2522 <indexterm>
2523 <primary>normalized</primary>
2524 </indexterm>
2525 <indexterm>
2526 <primary>Unicode normalization</primary>
2527 </indexterm>
2528 <type>text</type> <literal>IS</literal> <optional><literal>NOT</literal></optional> <optional><parameter>form</parameter></optional> <literal>NORMALIZED</literal>
2529 <returnvalue>boolean</returnvalue>
2530 </para>
2531 <para>
2532 Checks whether the string is in the specified Unicode normalization
2533 form. The optional <parameter>form</parameter> key word specifies the
2534 form: <literal>NFC</literal> (the default), <literal>NFD</literal>,
2535 <literal>NFKC</literal>, or <literal>NFKD</literal>. This expression can
2536 only be used when the server encoding is <literal>UTF8</literal>. Note
2537 that checking for normalization using this expression is often faster
2538 than normalizing possibly already normalized strings.
2539 </para>
2540 <para>
2541 <literal>U&amp;'\0061\0308bc' IS NFD NORMALIZED</literal>
2542 <returnvalue>t</returnvalue>
2543 </para></entry>
2544 </row>
2546 <row>
2547 <entry role="func_table_entry"><para role="func_signature">
2548 <indexterm>
2549 <primary>bit_length</primary>
2550 </indexterm>
2551 <function>bit_length</function> ( <type>text</type> )
2552 <returnvalue>integer</returnvalue>
2553 </para>
2554 <para>
2555 Returns number of bits in the string (8
2556 times the <function>octet_length</function>).
2557 </para>
2558 <para>
2559 <literal>bit_length('jose')</literal>
2560 <returnvalue>32</returnvalue>
2561 </para></entry>
2562 </row>
2564 <row>
2565 <entry role="func_table_entry"><para role="func_signature">
2566 <indexterm>
2567 <primary>char_length</primary>
2568 </indexterm>
2569 <indexterm>
2570 <primary>character string</primary>
2571 <secondary>length</secondary>
2572 </indexterm>
2573 <indexterm>
2574 <primary>length</primary>
2575 <secondary sortas="character string">of a character string</secondary>
2576 <see>character string, length</see>
2577 </indexterm>
2578 <function>char_length</function> ( <type>text</type> )
2579 <returnvalue>integer</returnvalue>
2580 </para>
2581 <para role="func_signature">
2582 <indexterm>
2583 <primary>character_length</primary>
2584 </indexterm>
2585 <function>character_length</function> ( <type>text</type> )
2586 <returnvalue>integer</returnvalue>
2587 </para>
2588 <para>
2589 Returns number of characters in the string.
2590 </para>
2591 <para>
2592 <literal>char_length('jos&eacute;')</literal>
2593 <returnvalue>4</returnvalue>
2594 </para></entry>
2595 </row>
2597 <row>
2598 <entry role="func_table_entry"><para role="func_signature">
2599 <indexterm>
2600 <primary>lower</primary>
2601 </indexterm>
2602 <function>lower</function> ( <type>text</type> )
2603 <returnvalue>text</returnvalue>
2604 </para>
2605 <para>
2606 Converts the string to all lower case, according to the rules of the
2607 database's locale.
2608 </para>
2609 <para>
2610 <literal>lower('TOM')</literal>
2611 <returnvalue>tom</returnvalue>
2612 </para></entry>
2613 </row>
2615 <row>
2616 <entry role="func_table_entry"><para role="func_signature">
2617 <indexterm>
2618 <primary>lpad</primary>
2619 </indexterm>
2620 <function>lpad</function> ( <parameter>string</parameter> <type>text</type>,
2621 <parameter>length</parameter> <type>integer</type>
2622 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
2623 <returnvalue>text</returnvalue>
2624 </para>
2625 <para>
2626 Extends the <parameter>string</parameter> to length
2627 <parameter>length</parameter> by prepending the characters
2628 <parameter>fill</parameter> (a space by default). If the
2629 <parameter>string</parameter> is already longer than
2630 <parameter>length</parameter> then it is truncated (on the right).
2631 </para>
2632 <para>
2633 <literal>lpad('hi', 5, 'xy')</literal>
2634 <returnvalue>xyxhi</returnvalue>
2635 </para></entry>
2636 </row>
2638 <row>
2639 <entry role="func_table_entry"><para role="func_signature">
2640 <indexterm>
2641 <primary>ltrim</primary>
2642 </indexterm>
2643 <function>ltrim</function> ( <parameter>string</parameter> <type>text</type>
2644 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2645 <returnvalue>text</returnvalue>
2646 </para>
2647 <para>
2648 Removes the longest string containing only characters in
2649 <parameter>characters</parameter> (a space by default) from the start of
2650 <parameter>string</parameter>.
2651 </para>
2652 <para>
2653 <literal>ltrim('zzzytest', 'xyz')</literal>
2654 <returnvalue>test</returnvalue>
2655 </para></entry>
2656 </row>
2658 <row>
2659 <entry role="func_table_entry"><para role="func_signature">
2660 <indexterm>
2661 <primary>normalize</primary>
2662 </indexterm>
2663 <indexterm>
2664 <primary>Unicode normalization</primary>
2665 </indexterm>
2666 <function>normalize</function> ( <type>text</type>
2667 <optional>, <parameter>form</parameter> </optional> )
2668 <returnvalue>text</returnvalue>
2669 </para>
2670 <para>
2671 Converts the string to the specified Unicode
2672 normalization form. The optional <parameter>form</parameter> key word
2673 specifies the form: <literal>NFC</literal> (the default),
2674 <literal>NFD</literal>, <literal>NFKC</literal>, or
2675 <literal>NFKD</literal>. This function can only be used when the
2676 server encoding is <literal>UTF8</literal>.
2677 </para>
2678 <para>
2679 <literal>normalize(U&amp;'\0061\0308bc', NFC)</literal>
2680 <returnvalue>U&amp;'\00E4bc'</returnvalue>
2681 </para></entry>
2682 </row>
2684 <row>
2685 <entry role="func_table_entry"><para role="func_signature">
2686 <indexterm>
2687 <primary>octet_length</primary>
2688 </indexterm>
2689 <function>octet_length</function> ( <type>text</type> )
2690 <returnvalue>integer</returnvalue>
2691 </para>
2692 <para>
2693 Returns number of bytes in the string.
2694 </para>
2695 <para>
2696 <literal>octet_length('jos&eacute;')</literal>
2697 <returnvalue>5</returnvalue> (if server encoding is UTF8)
2698 </para></entry>
2699 </row>
2701 <row>
2702 <entry role="func_table_entry"><para role="func_signature">
2703 <indexterm>
2704 <primary>octet_length</primary>
2705 </indexterm>
2706 <function>octet_length</function> ( <type>character</type> )
2707 <returnvalue>integer</returnvalue>
2708 </para>
2709 <para>
2710 Returns number of bytes in the string. Since this version of the
2711 function accepts type <type>character</type> directly, it will not
2712 strip trailing spaces.
2713 </para>
2714 <para>
2715 <literal>octet_length('abc '::character(4))</literal>
2716 <returnvalue>4</returnvalue>
2717 </para></entry>
2718 </row>
2720 <row>
2721 <entry role="func_table_entry"><para role="func_signature">
2722 <indexterm>
2723 <primary>overlay</primary>
2724 </indexterm>
2725 <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> )
2726 <returnvalue>text</returnvalue>
2727 </para>
2728 <para>
2729 Replaces the substring of <parameter>string</parameter> that starts at
2730 the <parameter>start</parameter>'th character and extends
2731 for <parameter>count</parameter> characters
2732 with <parameter>newsubstring</parameter>.
2733 If <parameter>count</parameter> is omitted, it defaults to the length
2734 of <parameter>newsubstring</parameter>.
2735 </para>
2736 <para>
2737 <literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal>
2738 <returnvalue>Thomas</returnvalue>
2739 </para></entry>
2740 </row>
2742 <row>
2743 <entry role="func_table_entry"><para role="func_signature">
2744 <indexterm>
2745 <primary>position</primary>
2746 </indexterm>
2747 <function>position</function> ( <parameter>substring</parameter> <type>text</type> <literal>IN</literal> <parameter>string</parameter> <type>text</type> )
2748 <returnvalue>integer</returnvalue>
2749 </para>
2750 <para>
2751 Returns first starting index of the specified
2752 <parameter>substring</parameter> within
2753 <parameter>string</parameter>, or zero if it's not present.
2754 </para>
2755 <para>
2756 <literal>position('om' in 'Thomas')</literal>
2757 <returnvalue>3</returnvalue>
2758 </para></entry>
2759 </row>
2761 <row>
2762 <entry role="func_table_entry"><para role="func_signature">
2763 <indexterm>
2764 <primary>rpad</primary>
2765 </indexterm>
2766 <function>rpad</function> ( <parameter>string</parameter> <type>text</type>,
2767 <parameter>length</parameter> <type>integer</type>
2768 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
2769 <returnvalue>text</returnvalue>
2770 </para>
2771 <para>
2772 Extends the <parameter>string</parameter> to length
2773 <parameter>length</parameter> by appending the characters
2774 <parameter>fill</parameter> (a space by default). If the
2775 <parameter>string</parameter> is already longer than
2776 <parameter>length</parameter> then it is truncated.
2777 </para>
2778 <para>
2779 <literal>rpad('hi', 5, 'xy')</literal>
2780 <returnvalue>hixyx</returnvalue>
2781 </para></entry>
2782 </row>
2784 <row>
2785 <entry role="func_table_entry"><para role="func_signature">
2786 <indexterm>
2787 <primary>rtrim</primary>
2788 </indexterm>
2789 <function>rtrim</function> ( <parameter>string</parameter> <type>text</type>
2790 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2791 <returnvalue>text</returnvalue>
2792 </para>
2793 <para>
2794 Removes the longest string containing only characters in
2795 <parameter>characters</parameter> (a space by default) from the end of
2796 <parameter>string</parameter>.
2797 </para>
2798 <para>
2799 <literal>rtrim('testxxzx', 'xyz')</literal>
2800 <returnvalue>test</returnvalue>
2801 </para></entry>
2802 </row>
2804 <row>
2805 <entry role="func_table_entry"><para role="func_signature">
2806 <indexterm>
2807 <primary>substring</primary>
2808 </indexterm>
2809 <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> )
2810 <returnvalue>text</returnvalue>
2811 </para>
2812 <para>
2813 Extracts the substring of <parameter>string</parameter> starting at
2814 the <parameter>start</parameter>'th character if that is specified,
2815 and stopping after <parameter>count</parameter> characters if that is
2816 specified. Provide at least one of <parameter>start</parameter>
2817 and <parameter>count</parameter>.
2818 </para>
2819 <para>
2820 <literal>substring('Thomas' from 2 for 3)</literal>
2821 <returnvalue>hom</returnvalue>
2822 </para>
2823 <para>
2824 <literal>substring('Thomas' from 3)</literal>
2825 <returnvalue>omas</returnvalue>
2826 </para>
2827 <para>
2828 <literal>substring('Thomas' for 2)</literal>
2829 <returnvalue>Th</returnvalue>
2830 </para></entry>
2831 </row>
2833 <row>
2834 <entry role="func_table_entry"><para role="func_signature">
2835 <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>FROM</literal> <parameter>pattern</parameter> <type>text</type> )
2836 <returnvalue>text</returnvalue>
2837 </para>
2838 <para>
2839 Extracts the first substring matching POSIX regular expression; see
2840 <xref linkend="functions-posix-regexp"/>.
2841 </para>
2842 <para>
2843 <literal>substring('Thomas' from '...$')</literal>
2844 <returnvalue>mas</returnvalue>
2845 </para></entry>
2846 </row>
2848 <row>
2849 <entry role="func_table_entry"><para role="func_signature">
2850 <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> )
2851 <returnvalue>text</returnvalue>
2852 </para>
2853 <para role="func_signature">
2854 <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> )
2855 <returnvalue>text</returnvalue>
2856 </para>
2857 <para>
2858 Extracts the first substring matching <acronym>SQL</acronym> regular expression;
2859 see <xref linkend="functions-similarto-regexp"/>. The first form has
2860 been specified since SQL:2003; the second form was only in SQL:1999
2861 and should be considered obsolete.
2862 </para>
2863 <para>
2864 <literal>substring('Thomas' similar '%#"o_a#"_' escape '#')</literal>
2865 <returnvalue>oma</returnvalue>
2866 </para></entry>
2867 </row>
2869 <row>
2870 <entry role="func_table_entry"><para role="func_signature">
2871 <indexterm>
2872 <primary>trim</primary>
2873 </indexterm>
2874 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
2875 <optional> <parameter>characters</parameter> <type>text</type> </optional> <literal>FROM</literal>
2876 <parameter>string</parameter> <type>text</type> )
2877 <returnvalue>text</returnvalue>
2878 </para>
2879 <para>
2880 Removes the longest string containing only characters in
2881 <parameter>characters</parameter> (a space by default) from the
2882 start, end, or both ends (<literal>BOTH</literal> is the default)
2883 of <parameter>string</parameter>.
2884 </para>
2885 <para>
2886 <literal>trim(both 'xyz' from 'yxTomxx')</literal>
2887 <returnvalue>Tom</returnvalue>
2888 </para></entry>
2889 </row>
2891 <row>
2892 <entry role="func_table_entry"><para role="func_signature">
2893 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
2894 <parameter>string</parameter> <type>text</type> <optional>,
2895 <parameter>characters</parameter> <type>text</type> </optional> )
2896 <returnvalue>text</returnvalue>
2897 </para>
2898 <para>
2899 This is a non-standard syntax for <function>trim()</function>.
2900 </para>
2901 <para>
2902 <literal>trim(both from 'yxTomxx', 'xyz')</literal>
2903 <returnvalue>Tom</returnvalue>
2904 </para></entry>
2905 </row>
2907 <row>
2908 <entry role="func_table_entry"><para role="func_signature">
2909 <indexterm>
2910 <primary>unicode_assigned</primary>
2911 </indexterm>
2912 <function>unicode_assigned</function> ( <type>text</type> )
2913 <returnvalue>boolean</returnvalue>
2914 </para>
2915 <para>
2916 Returns <literal>true</literal> if all characters in the string are
2917 assigned Unicode codepoints; <literal>false</literal> otherwise. This
2918 function can only be used when the server encoding is
2919 <literal>UTF8</literal>.
2920 </para></entry>
2921 </row>
2923 <row>
2924 <entry role="func_table_entry"><para role="func_signature">
2925 <indexterm>
2926 <primary>upper</primary>
2927 </indexterm>
2928 <function>upper</function> ( <type>text</type> )
2929 <returnvalue>text</returnvalue>
2930 </para>
2931 <para>
2932 Converts the string to all upper case, according to the rules of the
2933 database's locale.
2934 </para>
2935 <para>
2936 <literal>upper('tom')</literal>
2937 <returnvalue>TOM</returnvalue>
2938 </para></entry>
2939 </row>
2940 </tbody>
2941 </tgroup>
2942 </table>
2944 <para>
2945 Additional string manipulation functions and operators are available
2946 and are listed in <xref linkend="functions-string-other"/>. (Some of
2947 these are used internally to implement
2948 the <acronym>SQL</acronym>-standard string functions listed in
2949 <xref linkend="functions-string-sql"/>.)
2950 There are also pattern-matching operators, which are described in
2951 <xref linkend="functions-matching"/>, and operators for full-text
2952 search, which are described in <xref linkend="textsearch"/>.
2953 </para>
2955 <table id="functions-string-other">
2956 <title>Other String Functions and Operators</title>
2957 <tgroup cols="1">
2958 <thead>
2959 <row>
2960 <entry role="func_table_entry"><para role="func_signature">
2961 Function/Operator
2962 </para>
2963 <para>
2964 Description
2965 </para>
2966 <para>
2967 Example(s)
2968 </para></entry>
2969 </row>
2970 </thead>
2972 <tbody>
2973 <row>
2974 <entry role="func_table_entry"><para role="func_signature">
2975 <indexterm>
2976 <primary>character string</primary>
2977 <secondary>prefix test</secondary>
2978 </indexterm>
2979 <type>text</type> <literal>^@</literal> <type>text</type>
2980 <returnvalue>boolean</returnvalue>
2981 </para>
2982 <para>
2983 Returns true if the first string starts with the second string
2984 (equivalent to the <function>starts_with()</function> function).
2985 </para>
2986 <para>
2987 <literal>'alphabet' ^@ 'alph'</literal>
2988 <returnvalue>t</returnvalue>
2989 </para></entry>
2990 </row>
2992 <row>
2993 <entry role="func_table_entry"><para role="func_signature">
2994 <indexterm>
2995 <primary>ascii</primary>
2996 </indexterm>
2997 <function>ascii</function> ( <type>text</type> )
2998 <returnvalue>integer</returnvalue>
2999 </para>
3000 <para>
3001 Returns the numeric code of the first character of the argument.
3002 In <acronym>UTF8</acronym> encoding, returns the Unicode code point
3003 of the character. In other multibyte encodings, the argument must
3004 be an <acronym>ASCII</acronym> character.
3005 </para>
3006 <para>
3007 <literal>ascii('x')</literal>
3008 <returnvalue>120</returnvalue>
3009 </para></entry>
3010 </row>
3012 <row>
3013 <entry role="func_table_entry"><para role="func_signature">
3014 <indexterm>
3015 <primary>chr</primary>
3016 </indexterm>
3017 <function>chr</function> ( <type>integer</type> )
3018 <returnvalue>text</returnvalue>
3019 </para>
3020 <para>
3021 Returns the character with the given code. In <acronym>UTF8</acronym>
3022 encoding the argument is treated as a Unicode code point. In other
3023 multibyte encodings the argument must designate
3024 an <acronym>ASCII</acronym> character. <literal>chr(0)</literal> is
3025 disallowed because text data types cannot store that character.
3026 </para>
3027 <para>
3028 <literal>chr(65)</literal>
3029 <returnvalue>A</returnvalue>
3030 </para></entry>
3031 </row>
3033 <row>
3034 <entry role="func_table_entry"><para role="func_signature">
3035 <indexterm>
3036 <primary>concat</primary>
3037 </indexterm>
3038 <function>concat</function> ( <parameter>val1</parameter> <type>"any"</type>
3039 <optional>, <parameter>val2</parameter> <type>"any"</type> <optional>, ...</optional> </optional> )
3040 <returnvalue>text</returnvalue>
3041 </para>
3042 <para>
3043 Concatenates the text representations of all the arguments.
3044 NULL arguments are ignored.
3045 </para>
3046 <para>
3047 <literal>concat('abcde', 2, NULL, 22)</literal>
3048 <returnvalue>abcde222</returnvalue>
3049 </para></entry>
3050 </row>
3052 <row>
3053 <entry role="func_table_entry"><para role="func_signature">
3054 <indexterm>
3055 <primary>concat_ws</primary>
3056 </indexterm>
3057 <function>concat_ws</function> ( <parameter>sep</parameter> <type>text</type>,
3058 <parameter>val1</parameter> <type>"any"</type>
3059 <optional>, <parameter>val2</parameter> <type>"any"</type> <optional>, ...</optional> </optional> )
3060 <returnvalue>text</returnvalue>
3061 </para>
3062 <para>
3063 Concatenates all but the first argument, with separators. The first
3064 argument is used as the separator string, and should not be NULL.
3065 Other NULL arguments are ignored.
3066 </para>
3067 <para>
3068 <literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal>
3069 <returnvalue>abcde,2,22</returnvalue>
3070 </para></entry>
3071 </row>
3073 <row>
3074 <entry role="func_table_entry"><para role="func_signature">
3075 <indexterm>
3076 <primary>format</primary>
3077 </indexterm>
3078 <function>format</function> ( <parameter>formatstr</parameter> <type>text</type>
3079 <optional>, <parameter>formatarg</parameter> <type>"any"</type> <optional>, ...</optional> </optional> )
3080 <returnvalue>text</returnvalue>
3081 </para>
3082 <para>
3083 Formats arguments according to a format string;
3084 see <xref linkend="functions-string-format"/>.
3085 This function is similar to the C function <function>sprintf</function>.
3086 </para>
3087 <para>
3088 <literal>format('Hello %s, %1$s', 'World')</literal>
3089 <returnvalue>Hello World, World</returnvalue>
3090 </para></entry>
3091 </row>
3093 <row>
3094 <entry role="func_table_entry"><para role="func_signature">
3095 <indexterm>
3096 <primary>initcap</primary>
3097 </indexterm>
3098 <function>initcap</function> ( <type>text</type> )
3099 <returnvalue>text</returnvalue>
3100 </para>
3101 <para>
3102 Converts the first letter of each word to upper case and the
3103 rest to lower case. Words are sequences of alphanumeric
3104 characters separated by non-alphanumeric characters.
3105 </para>
3106 <para>
3107 <literal>initcap('hi THOMAS')</literal>
3108 <returnvalue>Hi Thomas</returnvalue>
3109 </para></entry>
3110 </row>
3112 <row>
3113 <entry role="func_table_entry"><para role="func_signature">
3114 <indexterm>
3115 <primary>left</primary>
3116 </indexterm>
3117 <function>left</function> ( <parameter>string</parameter> <type>text</type>,
3118 <parameter>n</parameter> <type>integer</type> )
3119 <returnvalue>text</returnvalue>
3120 </para>
3121 <para>
3122 Returns first <parameter>n</parameter> characters in the
3123 string, or when <parameter>n</parameter> is negative, returns
3124 all but last |<parameter>n</parameter>| characters.
3125 </para>
3126 <para>
3127 <literal>left('abcde', 2)</literal>
3128 <returnvalue>ab</returnvalue>
3129 </para></entry>
3130 </row>
3132 <row>
3133 <entry role="func_table_entry"><para role="func_signature">
3134 <indexterm>
3135 <primary>length</primary>
3136 </indexterm>
3137 <function>length</function> ( <type>text</type> )
3138 <returnvalue>integer</returnvalue>
3139 </para>
3140 <para>
3141 Returns the number of characters in the string.
3142 </para>
3143 <para>
3144 <literal>length('jose')</literal>
3145 <returnvalue>4</returnvalue>
3146 </para></entry>
3147 </row>
3149 <row>
3150 <entry role="func_table_entry"><para role="func_signature">
3151 <indexterm>
3152 <primary>md5</primary>
3153 </indexterm>
3154 <function>md5</function> ( <type>text</type> )
3155 <returnvalue>text</returnvalue>
3156 </para>
3157 <para>
3158 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
3159 the argument, with the result written in hexadecimal.
3160 </para>
3161 <para>
3162 <literal>md5('abc')</literal>
3163 <returnvalue>900150983cd24fb0&zwsp;d6963f7d28e17f72</returnvalue>
3164 </para></entry>
3165 </row>
3167 <row>
3168 <entry role="func_table_entry"><para role="func_signature">
3169 <indexterm>
3170 <primary>parse_ident</primary>
3171 </indexterm>
3172 <function>parse_ident</function> ( <parameter>qualified_identifier</parameter> <type>text</type>
3173 <optional>, <parameter>strict_mode</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>true</literal> </optional> )
3174 <returnvalue>text[]</returnvalue>
3175 </para>
3176 <para>
3177 Splits <parameter>qualified_identifier</parameter> into an array of
3178 identifiers, removing any quoting of individual identifiers. By
3179 default, extra characters after the last identifier are considered an
3180 error; but if the second parameter is <literal>false</literal>, then such
3181 extra characters are ignored. (This behavior is useful for parsing
3182 names for objects like functions.) Note that this function does not
3183 truncate over-length identifiers. If you want truncation you can cast
3184 the result to <type>name[]</type>.
3185 </para>
3186 <para>
3187 <literal>parse_ident('"SomeSchema".someTable')</literal>
3188 <returnvalue>{SomeSchema,sometable}</returnvalue>
3189 </para></entry>
3190 </row>
3192 <row>
3193 <entry role="func_table_entry"><para role="func_signature">
3194 <indexterm>
3195 <primary>pg_client_encoding</primary>
3196 </indexterm>
3197 <function>pg_client_encoding</function> ( )
3198 <returnvalue>name</returnvalue>
3199 </para>
3200 <para>
3201 Returns current client encoding name.
3202 </para>
3203 <para>
3204 <literal>pg_client_encoding()</literal>
3205 <returnvalue>UTF8</returnvalue>
3206 </para></entry>
3207 </row>
3209 <row>
3210 <entry role="func_table_entry"><para role="func_signature">
3211 <indexterm>
3212 <primary>quote_ident</primary>
3213 </indexterm>
3214 <function>quote_ident</function> ( <type>text</type> )
3215 <returnvalue>text</returnvalue>
3216 </para>
3217 <para>
3218 Returns the given string suitably quoted to be used as an identifier
3219 in an <acronym>SQL</acronym> statement string.
3220 Quotes are added only if necessary (i.e., if the string contains
3221 non-identifier characters or would be case-folded).
3222 Embedded quotes are properly doubled.
3223 See also <xref linkend="plpgsql-quote-literal-example"/>.
3224 </para>
3225 <para>
3226 <literal>quote_ident('Foo bar')</literal>
3227 <returnvalue>"Foo bar"</returnvalue>
3228 </para></entry>
3229 </row>
3231 <row>
3232 <entry role="func_table_entry"><para role="func_signature">
3233 <indexterm>
3234 <primary>quote_literal</primary>
3235 </indexterm>
3236 <function>quote_literal</function> ( <type>text</type> )
3237 <returnvalue>text</returnvalue>
3238 </para>
3239 <para>
3240 Returns the given string suitably quoted to be used as a string literal
3241 in an <acronym>SQL</acronym> statement string.
3242 Embedded single-quotes and backslashes are properly doubled.
3243 Note that <function>quote_literal</function> returns null on null
3244 input; if the argument might be null,
3245 <function>quote_nullable</function> is often more suitable.
3246 See also <xref linkend="plpgsql-quote-literal-example"/>.
3247 </para>
3248 <para>
3249 <literal>quote_literal(E'O\'Reilly')</literal>
3250 <returnvalue>'O''Reilly'</returnvalue>
3251 </para></entry>
3252 </row>
3254 <row>
3255 <entry role="func_table_entry"><para role="func_signature">
3256 <function>quote_literal</function> ( <type>anyelement</type> )
3257 <returnvalue>text</returnvalue>
3258 </para>
3259 <para>
3260 Converts the given value to text and then quotes it as a literal.
3261 Embedded single-quotes and backslashes are properly doubled.
3262 </para>
3263 <para>
3264 <literal>quote_literal(42.5)</literal>
3265 <returnvalue>'42.5'</returnvalue>
3266 </para></entry>
3267 </row>
3269 <row>
3270 <entry role="func_table_entry"><para role="func_signature">
3271 <indexterm>
3272 <primary>quote_nullable</primary>
3273 </indexterm>
3274 <function>quote_nullable</function> ( <type>text</type> )
3275 <returnvalue>text</returnvalue>
3276 </para>
3277 <para>
3278 Returns the given string suitably quoted to be used as a string literal
3279 in an <acronym>SQL</acronym> statement string; or, if the argument
3280 is null, returns <literal>NULL</literal>.
3281 Embedded single-quotes and backslashes are properly doubled.
3282 See also <xref linkend="plpgsql-quote-literal-example"/>.
3283 </para>
3284 <para>
3285 <literal>quote_nullable(NULL)</literal>
3286 <returnvalue>NULL</returnvalue>
3287 </para></entry>
3288 </row>
3290 <row>
3291 <entry role="func_table_entry"><para role="func_signature">
3292 <function>quote_nullable</function> ( <type>anyelement</type> )
3293 <returnvalue>text</returnvalue>
3294 </para>
3295 <para>
3296 Converts the given value to text and then quotes it as a literal;
3297 or, if the argument is null, returns <literal>NULL</literal>.
3298 Embedded single-quotes and backslashes are properly doubled.
3299 </para>
3300 <para>
3301 <literal>quote_nullable(42.5)</literal>
3302 <returnvalue>'42.5'</returnvalue>
3303 </para></entry>
3304 </row>
3306 <row>
3307 <entry role="func_table_entry"><para role="func_signature">
3308 <indexterm>
3309 <primary>regexp_count</primary>
3310 </indexterm>
3311 <function>regexp_count</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3312 <optional>, <parameter>start</parameter> <type>integer</type>
3313 <optional>, <parameter>flags</parameter> <type>text</type> </optional> </optional> )
3314 <returnvalue>integer</returnvalue>
3315 </para>
3316 <para>
3317 Returns the number of times the POSIX regular
3318 expression <parameter>pattern</parameter> matches in
3319 the <parameter>string</parameter>; see
3320 <xref linkend="functions-posix-regexp"/>.
3321 </para>
3322 <para>
3323 <literal>regexp_count('123456789012', '\d\d\d', 2)</literal>
3324 <returnvalue>3</returnvalue>
3325 </para></entry>
3326 </row>
3328 <row>
3329 <entry role="func_table_entry"><para role="func_signature">
3330 <indexterm>
3331 <primary>regexp_instr</primary>
3332 </indexterm>
3333 <function>regexp_instr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3334 <optional>, <parameter>start</parameter> <type>integer</type>
3335 <optional>, <parameter>N</parameter> <type>integer</type>
3336 <optional>, <parameter>endoption</parameter> <type>integer</type>
3337 <optional>, <parameter>flags</parameter> <type>text</type>
3338 <optional>, <parameter>subexpr</parameter> <type>integer</type> </optional> </optional> </optional> </optional> </optional> )
3339 <returnvalue>integer</returnvalue>
3340 </para>
3341 <para>
3342 Returns the position within <parameter>string</parameter> where
3343 the <parameter>N</parameter>'th match of the POSIX regular
3344 expression <parameter>pattern</parameter> occurs, or zero if there is
3345 no such match; see <xref linkend="functions-posix-regexp"/>.
3346 </para>
3347 <para>
3348 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i')</literal>
3349 <returnvalue>3</returnvalue>
3350 </para>
3351 <para>
3352 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i', 2)</literal>
3353 <returnvalue>5</returnvalue>
3354 </para></entry>
3355 </row>
3357 <row>
3358 <entry role="func_table_entry"><para role="func_signature">
3359 <indexterm>
3360 <primary>regexp_like</primary>
3361 </indexterm>
3362 <function>regexp_like</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3363 <optional>, <parameter>flags</parameter> <type>text</type> </optional> )
3364 <returnvalue>boolean</returnvalue>
3365 </para>
3366 <para>
3367 Checks whether a match of the POSIX regular
3368 expression <parameter>pattern</parameter> occurs
3369 within <parameter>string</parameter>; see
3370 <xref linkend="functions-posix-regexp"/>.
3371 </para>
3372 <para>
3373 <literal>regexp_like('Hello World', 'world$', 'i')</literal>
3374 <returnvalue>t</returnvalue>
3375 </para></entry>
3376 </row>
3378 <row>
3379 <entry role="func_table_entry"><para role="func_signature">
3380 <indexterm>
3381 <primary>regexp_match</primary>
3382 </indexterm>
3383 <function>regexp_match</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> <optional>, <parameter>flags</parameter> <type>text</type> </optional> )
3384 <returnvalue>text[]</returnvalue>
3385 </para>
3386 <para>
3387 Returns substrings within the first match of the POSIX regular
3388 expression <parameter>pattern</parameter> to
3389 the <parameter>string</parameter>; see
3390 <xref linkend="functions-posix-regexp"/>.
3391 </para>
3392 <para>
3393 <literal>regexp_match('foobarbequebaz', '(bar)(beque)')</literal>
3394 <returnvalue>{bar,beque}</returnvalue>
3395 </para></entry>
3396 </row>
3398 <row>
3399 <entry role="func_table_entry"><para role="func_signature">
3400 <indexterm>
3401 <primary>regexp_matches</primary>
3402 </indexterm>
3403 <function>regexp_matches</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> <optional>, <parameter>flags</parameter> <type>text</type> </optional> )
3404 <returnvalue>setof text[]</returnvalue>
3405 </para>
3406 <para>
3407 Returns substrings within the first match of the POSIX regular
3408 expression <parameter>pattern</parameter> to
3409 the <parameter>string</parameter>, or substrings within all
3410 such matches if the <literal>g</literal> flag is used;
3411 see <xref linkend="functions-posix-regexp"/>.
3412 </para>
3413 <para>
3414 <literal>regexp_matches('foobarbequebaz', 'ba.', 'g')</literal>
3415 <returnvalue></returnvalue>
3416 <programlisting>
3417 {bar}
3418 {baz}
3419 </programlisting>
3420 </para></entry>
3421 </row>
3423 <row>
3424 <entry role="func_table_entry"><para role="func_signature">
3425 <indexterm>
3426 <primary>regexp_replace</primary>
3427 </indexterm>
3428 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>
3429 <optional>, <parameter>flags</parameter> <type>text</type> </optional> )
3430 <returnvalue>text</returnvalue>
3431 </para>
3432 <para>
3433 Replaces the substring that is the first match to the POSIX
3434 regular expression <parameter>pattern</parameter>, or all such
3435 matches if the <literal>g</literal> flag is used; see
3436 <xref linkend="functions-posix-regexp"/>.
3437 </para>
3438 <para>
3439 <literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal>
3440 <returnvalue>ThM</returnvalue>
3441 </para></entry>
3442 </row>
3444 <row>
3445 <entry role="func_table_entry"><para role="func_signature">
3446 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>,
3447 <parameter>start</parameter> <type>integer</type>
3448 <optional>, <parameter>N</parameter> <type>integer</type>
3449 <optional>, <parameter>flags</parameter> <type>text</type> </optional> </optional> )
3450 <returnvalue>text</returnvalue>
3451 </para>
3452 <para>
3453 Replaces the substring that is the <parameter>N</parameter>'th
3454 match to the POSIX regular expression <parameter>pattern</parameter>,
3455 or all such matches if <parameter>N</parameter> is zero, with the
3456 search beginning at the <parameter>start</parameter>'th character
3457 of <parameter>string</parameter>. If <parameter>N</parameter> is
3458 omitted, it defaults to 1. See
3459 <xref linkend="functions-posix-regexp"/>.
3460 </para>
3461 <para>
3462 <literal>regexp_replace('Thomas', '.', 'X', 3, 2)</literal>
3463 <returnvalue>ThoXas</returnvalue>
3464 </para>
3465 <para>
3466 <literal>regexp_replace(string=>'hello world', pattern=>'l', replacement=>'XX', start=>1, "N"=>2)</literal>
3467 <returnvalue>helXXo world</returnvalue>
3468 </para></entry>
3469 </row>
3471 <row>
3472 <entry role="func_table_entry"><para role="func_signature">
3473 <indexterm>
3474 <primary>regexp_split_to_array</primary>
3475 </indexterm>
3476 <function>regexp_split_to_array</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> <optional>, <parameter>flags</parameter> <type>text</type> </optional> )
3477 <returnvalue>text[]</returnvalue>
3478 </para>
3479 <para>
3480 Splits <parameter>string</parameter> using a POSIX regular
3481 expression as the delimiter, producing an array of results; see
3482 <xref linkend="functions-posix-regexp"/>.
3483 </para>
3484 <para>
3485 <literal>regexp_split_to_array('hello world', '\s+')</literal>
3486 <returnvalue>{hello,world}</returnvalue>
3487 </para></entry>
3488 </row>
3490 <row>
3491 <entry role="func_table_entry"><para role="func_signature">
3492 <indexterm>
3493 <primary>regexp_split_to_table</primary>
3494 </indexterm>
3495 <function>regexp_split_to_table</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> <optional>, <parameter>flags</parameter> <type>text</type> </optional> )
3496 <returnvalue>setof text</returnvalue>
3497 </para>
3498 <para>
3499 Splits <parameter>string</parameter> using a POSIX regular
3500 expression as the delimiter, producing a set of results; see
3501 <xref linkend="functions-posix-regexp"/>.
3502 </para>
3503 <para>
3504 <literal>regexp_split_to_table('hello world', '\s+')</literal>
3505 <returnvalue></returnvalue>
3506 <programlisting>
3507 hello
3508 world
3509 </programlisting>
3510 </para></entry>
3511 </row>
3513 <row>
3514 <entry role="func_table_entry"><para role="func_signature">
3515 <indexterm>
3516 <primary>regexp_substr</primary>
3517 </indexterm>
3518 <function>regexp_substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3519 <optional>, <parameter>start</parameter> <type>integer</type>
3520 <optional>, <parameter>N</parameter> <type>integer</type>
3521 <optional>, <parameter>flags</parameter> <type>text</type>
3522 <optional>, <parameter>subexpr</parameter> <type>integer</type> </optional> </optional> </optional> </optional> )
3523 <returnvalue>text</returnvalue>
3524 </para>
3525 <para>
3526 Returns the substring within <parameter>string</parameter> that
3527 matches the <parameter>N</parameter>'th occurrence of the POSIX
3528 regular expression <parameter>pattern</parameter>,
3529 or <literal>NULL</literal> if there is no such match; see
3530 <xref linkend="functions-posix-regexp"/>.
3531 </para>
3532 <para>
3533 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i')</literal>
3534 <returnvalue>CDEF</returnvalue>
3535 </para>
3536 <para>
3537 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i', 2)</literal>
3538 <returnvalue>EF</returnvalue>
3539 </para></entry>
3540 </row>
3542 <row>
3543 <entry role="func_table_entry"><para role="func_signature">
3544 <indexterm>
3545 <primary>repeat</primary>
3546 </indexterm>
3547 <function>repeat</function> ( <parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>integer</type> )
3548 <returnvalue>text</returnvalue>
3549 </para>
3550 <para>
3551 Repeats <parameter>string</parameter> the specified
3552 <parameter>number</parameter> of times.
3553 </para>
3554 <para>
3555 <literal>repeat('Pg', 4)</literal>
3556 <returnvalue>PgPgPgPg</returnvalue>
3557 </para></entry>
3558 </row>
3560 <row>
3561 <entry role="func_table_entry"><para role="func_signature">
3562 <indexterm>
3563 <primary>replace</primary>
3564 </indexterm>
3565 <function>replace</function> ( <parameter>string</parameter> <type>text</type>,
3566 <parameter>from</parameter> <type>text</type>,
3567 <parameter>to</parameter> <type>text</type> )
3568 <returnvalue>text</returnvalue>
3569 </para>
3570 <para>
3571 Replaces all occurrences in <parameter>string</parameter> of
3572 substring <parameter>from</parameter> with
3573 substring <parameter>to</parameter>.
3574 </para>
3575 <para>
3576 <literal>replace('abcdefabcdef', 'cd', 'XX')</literal>
3577 <returnvalue>abXXefabXXef</returnvalue>
3578 </para></entry>
3579 </row>
3581 <row>
3582 <entry role="func_table_entry"><para role="func_signature">
3583 <indexterm>
3584 <primary>reverse</primary>
3585 </indexterm>
3586 <function>reverse</function> ( <type>text</type> )
3587 <returnvalue>text</returnvalue>
3588 </para>
3589 <para>
3590 Reverses the order of the characters in the string.
3591 </para>
3592 <para>
3593 <literal>reverse('abcde')</literal>
3594 <returnvalue>edcba</returnvalue>
3595 </para></entry>
3596 </row>
3598 <row>
3599 <entry role="func_table_entry"><para role="func_signature">
3600 <indexterm>
3601 <primary>right</primary>
3602 </indexterm>
3603 <function>right</function> ( <parameter>string</parameter> <type>text</type>,
3604 <parameter>n</parameter> <type>integer</type> )
3605 <returnvalue>text</returnvalue>
3606 </para>
3607 <para>
3608 Returns last <parameter>n</parameter> characters in the string,
3609 or when <parameter>n</parameter> is negative, returns all but
3610 first |<parameter>n</parameter>| characters.
3611 </para>
3612 <para>
3613 <literal>right('abcde', 2)</literal>
3614 <returnvalue>de</returnvalue>
3615 </para></entry>
3616 </row>
3618 <row>
3619 <entry role="func_table_entry"><para role="func_signature">
3620 <indexterm>
3621 <primary>split_part</primary>
3622 </indexterm>
3623 <function>split_part</function> ( <parameter>string</parameter> <type>text</type>,
3624 <parameter>delimiter</parameter> <type>text</type>,
3625 <parameter>n</parameter> <type>integer</type> )
3626 <returnvalue>text</returnvalue>
3627 </para>
3628 <para>
3629 Splits <parameter>string</parameter> at occurrences
3630 of <parameter>delimiter</parameter> and returns
3631 the <parameter>n</parameter>'th field (counting from one),
3632 or when <parameter>n</parameter> is negative, returns
3633 the |<parameter>n</parameter>|'th-from-last field.
3634 </para>
3635 <para>
3636 <literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal>
3637 <returnvalue>def</returnvalue>
3638 </para>
3639 <para>
3640 <literal>split_part('abc,def,ghi,jkl', ',', -2)</literal>
3641 <returnvalue>ghi</returnvalue>
3642 </para></entry>
3643 </row>
3645 <row>
3646 <entry role="func_table_entry"><para role="func_signature">
3647 <indexterm>
3648 <primary>starts_with</primary>
3649 </indexterm>
3650 <function>starts_with</function> ( <parameter>string</parameter> <type>text</type>, <parameter>prefix</parameter> <type>text</type> )
3651 <returnvalue>boolean</returnvalue>
3652 </para>
3653 <para>
3654 Returns true if <parameter>string</parameter> starts
3655 with <parameter>prefix</parameter>.
3656 </para>
3657 <para>
3658 <literal>starts_with('alphabet', 'alph')</literal>
3659 <returnvalue>t</returnvalue>
3660 </para></entry>
3661 </row>
3663 <row>
3664 <entry role="func_table_entry"><para role="func_signature">
3665 <indexterm id="function-string-to-array">
3666 <primary>string_to_array</primary>
3667 </indexterm>
3668 <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> )
3669 <returnvalue>text[]</returnvalue>
3670 </para>
3671 <para>
3672 Splits the <parameter>string</parameter> at occurrences
3673 of <parameter>delimiter</parameter> and forms the resulting fields
3674 into a <type>text</type> array.
3675 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3676 each character in the <parameter>string</parameter> will become a
3677 separate element in the array.
3678 If <parameter>delimiter</parameter> is an empty string, then
3679 the <parameter>string</parameter> is treated as a single field.
3680 If <parameter>null_string</parameter> is supplied and is
3681 not <literal>NULL</literal>, fields matching that string are
3682 replaced by <literal>NULL</literal>.
3683 See also <link linkend="function-array-to-string"><function>array_to_string</function></link>.
3684 </para>
3685 <para>
3686 <literal>string_to_array('xx~~yy~~zz', '~~', 'yy')</literal>
3687 <returnvalue>{xx,NULL,zz}</returnvalue>
3688 </para></entry>
3689 </row>
3691 <row>
3692 <entry role="func_table_entry"><para role="func_signature">
3693 <indexterm>
3694 <primary>string_to_table</primary>
3695 </indexterm>
3696 <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> )
3697 <returnvalue>setof text</returnvalue>
3698 </para>
3699 <para>
3700 Splits the <parameter>string</parameter> at occurrences
3701 of <parameter>delimiter</parameter> and returns the resulting fields
3702 as a set of <type>text</type> rows.
3703 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3704 each character in the <parameter>string</parameter> will become a
3705 separate row of the result.
3706 If <parameter>delimiter</parameter> is an empty string, then
3707 the <parameter>string</parameter> is treated as a single field.
3708 If <parameter>null_string</parameter> is supplied and is
3709 not <literal>NULL</literal>, fields matching that string are
3710 replaced by <literal>NULL</literal>.
3711 </para>
3712 <para>
3713 <literal>string_to_table('xx~^~yy~^~zz', '~^~', 'yy')</literal>
3714 <returnvalue></returnvalue>
3715 <programlisting>
3717 NULL
3719 </programlisting>
3720 </para></entry>
3721 </row>
3723 <row>
3724 <entry role="func_table_entry"><para role="func_signature">
3725 <indexterm>
3726 <primary>strpos</primary>
3727 </indexterm>
3728 <function>strpos</function> ( <parameter>string</parameter> <type>text</type>, <parameter>substring</parameter> <type>text</type> )
3729 <returnvalue>integer</returnvalue>
3730 </para>
3731 <para>
3732 Returns first starting index of the specified <parameter>substring</parameter>
3733 within <parameter>string</parameter>, or zero if it's not present.
3734 (Same as <literal>position(<parameter>substring</parameter> in
3735 <parameter>string</parameter>)</literal>, but note the reversed
3736 argument order.)
3737 </para>
3738 <para>
3739 <literal>strpos('high', 'ig')</literal>
3740 <returnvalue>2</returnvalue>
3741 </para></entry>
3742 </row>
3744 <row>
3745 <entry role="func_table_entry"><para role="func_signature">
3746 <indexterm>
3747 <primary>substr</primary>
3748 </indexterm>
3749 <function>substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
3750 <returnvalue>text</returnvalue>
3751 </para>
3752 <para>
3753 Extracts the substring of <parameter>string</parameter> starting at
3754 the <parameter>start</parameter>'th character,
3755 and extending for <parameter>count</parameter> characters if that is
3756 specified. (Same
3757 as <literal>substring(<parameter>string</parameter>
3758 from <parameter>start</parameter>
3759 for <parameter>count</parameter>)</literal>.)
3760 </para>
3761 <para>
3762 <literal>substr('alphabet', 3)</literal>
3763 <returnvalue>phabet</returnvalue>
3764 </para>
3765 <para>
3766 <literal>substr('alphabet', 3, 2)</literal>
3767 <returnvalue>ph</returnvalue>
3768 </para></entry>
3769 </row>
3771 <row>
3772 <entry role="func_table_entry"><para role="func_signature">
3773 <indexterm>
3774 <primary>to_ascii</primary>
3775 </indexterm>
3776 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type> )
3777 <returnvalue>text</returnvalue>
3778 </para>
3779 <para role="func_signature">
3780 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3781 <parameter>encoding</parameter> <type>name</type> )
3782 <returnvalue>text</returnvalue>
3783 </para>
3784 <para role="func_signature">
3785 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3786 <parameter>encoding</parameter> <type>integer</type> )
3787 <returnvalue>text</returnvalue>
3788 </para>
3789 <para>
3790 Converts <parameter>string</parameter> to <acronym>ASCII</acronym>
3791 from another encoding, which may be identified by name or number.
3792 If <parameter>encoding</parameter> is omitted the database encoding
3793 is assumed (which in practice is the only useful case).
3794 The conversion consists primarily of dropping accents.
3795 Conversion is only supported
3796 from <literal>LATIN1</literal>, <literal>LATIN2</literal>,
3797 <literal>LATIN9</literal>, and <literal>WIN1250</literal> encodings.
3798 (See the <xref linkend="unaccent"/> module for another, more flexible
3799 solution.)
3800 </para>
3801 <para>
3802 <literal>to_ascii('Kar&eacute;l')</literal>
3803 <returnvalue>Karel</returnvalue>
3804 </para></entry>
3805 </row>
3807 <row>
3808 <entry role="func_table_entry"><para role="func_signature">
3809 <indexterm>
3810 <primary>to_bin</primary>
3811 </indexterm>
3812 <function>to_bin</function> ( <type>integer</type> )
3813 <returnvalue>text</returnvalue>
3814 </para>
3815 <para role="func_signature">
3816 <function>to_bin</function> ( <type>bigint</type> )
3817 <returnvalue>text</returnvalue>
3818 </para>
3819 <para>
3820 Converts the number to its equivalent two's complement binary
3821 representation.
3822 </para>
3823 <para>
3824 <literal>to_bin(2147483647)</literal>
3825 <returnvalue>1111111111111111111111111111111</returnvalue>
3826 </para>
3827 <para>
3828 <literal>to_bin(-1234)</literal>
3829 <returnvalue>11111111111111111111101100101110</returnvalue>
3830 </para></entry>
3831 </row>
3833 <row>
3834 <entry role="func_table_entry"><para role="func_signature">
3835 <indexterm>
3836 <primary>to_hex</primary>
3837 </indexterm>
3838 <function>to_hex</function> ( <type>integer</type> )
3839 <returnvalue>text</returnvalue>
3840 </para>
3841 <para role="func_signature">
3842 <function>to_hex</function> ( <type>bigint</type> )
3843 <returnvalue>text</returnvalue>
3844 </para>
3845 <para>
3846 Converts the number to its equivalent two's complement hexadecimal
3847 representation.
3848 </para>
3849 <para>
3850 <literal>to_hex(2147483647)</literal>
3851 <returnvalue>7fffffff</returnvalue>
3852 </para>
3853 <para>
3854 <literal>to_hex(-1234)</literal>
3855 <returnvalue>fffffb2e</returnvalue>
3856 </para></entry>
3857 </row>
3859 <row>
3860 <entry role="func_table_entry"><para role="func_signature">
3861 <indexterm>
3862 <primary>to_oct</primary>
3863 </indexterm>
3864 <function>to_oct</function> ( <type>integer</type> )
3865 <returnvalue>text</returnvalue>
3866 </para>
3867 <para role="func_signature">
3868 <function>to_oct</function> ( <type>bigint</type> )
3869 <returnvalue>text</returnvalue>
3870 </para>
3871 <para>
3872 Converts the number to its equivalent two's complement octal
3873 representation.
3874 </para>
3875 <para>
3876 <literal>to_oct(2147483647)</literal>
3877 <returnvalue>17777777777</returnvalue>
3878 </para>
3879 <para>
3880 <literal>to_oct(-1234)</literal>
3881 <returnvalue>37777775456</returnvalue>
3882 </para></entry>
3883 </row>
3885 <row>
3886 <entry role="func_table_entry"><para role="func_signature">
3887 <indexterm>
3888 <primary>translate</primary>
3889 </indexterm>
3890 <function>translate</function> ( <parameter>string</parameter> <type>text</type>,
3891 <parameter>from</parameter> <type>text</type>,
3892 <parameter>to</parameter> <type>text</type> )
3893 <returnvalue>text</returnvalue>
3894 </para>
3895 <para>
3896 Replaces each character in <parameter>string</parameter> that
3897 matches a character in the <parameter>from</parameter> set with the
3898 corresponding character in the <parameter>to</parameter>
3899 set. If <parameter>from</parameter> is longer than
3900 <parameter>to</parameter>, occurrences of the extra characters in
3901 <parameter>from</parameter> are deleted.
3902 </para>
3903 <para>
3904 <literal>translate('12345', '143', 'ax')</literal>
3905 <returnvalue>a2x5</returnvalue>
3906 </para></entry>
3907 </row>
3909 <row>
3910 <entry role="func_table_entry"><para role="func_signature">
3911 <indexterm>
3912 <primary>unistr</primary>
3913 </indexterm>
3914 <function>unistr</function> ( <type>text</type> )
3915 <returnvalue>text</returnvalue>
3916 </para>
3917 <para>
3918 Evaluate escaped Unicode characters in the argument. Unicode characters
3919 can be specified as
3920 <literal>\<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3921 digits), <literal>\+<replaceable>XXXXXX</replaceable></literal> (6
3922 hexadecimal digits),
3923 <literal>\u<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3924 digits), or <literal>\U<replaceable>XXXXXXXX</replaceable></literal>
3925 (8 hexadecimal digits). To specify a backslash, write two
3926 backslashes. All other characters are taken literally.
3927 </para>
3929 <para>
3930 If the server encoding is not UTF-8, the Unicode code point identified
3931 by one of these escape sequences is converted to the actual server
3932 encoding; an error is reported if that's not possible.
3933 </para>
3935 <para>
3936 This function provides a (non-standard) alternative to string
3937 constants with Unicode escapes (see <xref
3938 linkend="sql-syntax-strings-uescape"/>).
3939 </para>
3941 <para>
3942 <literal>unistr('d\0061t\+000061')</literal>
3943 <returnvalue>data</returnvalue>
3944 </para>
3945 <para>
3946 <literal>unistr('d\u0061t\U00000061')</literal>
3947 <returnvalue>data</returnvalue>
3948 </para></entry>
3949 </row>
3951 </tbody>
3952 </tgroup>
3953 </table>
3955 <para>
3956 The <function>concat</function>, <function>concat_ws</function> and
3957 <function>format</function> functions are variadic, so it is possible to
3958 pass the values to be concatenated or formatted as an array marked with
3959 the <literal>VARIADIC</literal> keyword (see <xref
3960 linkend="xfunc-sql-variadic-functions"/>). The array's elements are
3961 treated as if they were separate ordinary arguments to the function.
3962 If the variadic array argument is NULL, <function>concat</function>
3963 and <function>concat_ws</function> return NULL, but
3964 <function>format</function> treats a NULL as a zero-element array.
3965 </para>
3967 <para>
3968 See also the aggregate function <function>string_agg</function> in
3969 <xref linkend="functions-aggregate"/>, and the functions for
3970 converting between strings and the <type>bytea</type> type in
3971 <xref linkend="functions-binarystring-conversions"/>.
3972 </para>
3974 <sect2 id="functions-string-format">
3975 <title><function>format</function></title>
3977 <indexterm>
3978 <primary>format</primary>
3979 </indexterm>
3981 <para>
3982 The function <function>format</function> produces output formatted according to
3983 a format string, in a style similar to the C function
3984 <function>sprintf</function>.
3985 </para>
3987 <para>
3988 <synopsis>
3989 <function>format</function>(<parameter>formatstr</parameter> <type>text</type> <optional>, <parameter>formatarg</parameter> <type>"any"</type> <optional>, ...</optional> </optional>)
3990 </synopsis>
3991 <parameter>formatstr</parameter> is a format string that specifies how the
3992 result should be formatted. Text in the format string is copied
3993 directly to the result, except where <firstterm>format specifiers</firstterm> are
3994 used. Format specifiers act as placeholders in the string, defining how
3995 subsequent function arguments should be formatted and inserted into the
3996 result. Each <parameter>formatarg</parameter> argument is converted to text
3997 according to the usual output rules for its data type, and then formatted
3998 and inserted into the result string according to the format specifier(s).
3999 </para>
4001 <para>
4002 Format specifiers are introduced by a <literal>%</literal> character and have
4003 the form
4004 <synopsis>
4005 %[<parameter>position</parameter>][<parameter>flags</parameter>][<parameter>width</parameter>]<parameter>type</parameter>
4006 </synopsis>
4007 where the component fields are:
4009 <variablelist>
4010 <varlistentry>
4011 <term><parameter>position</parameter> (optional)</term>
4012 <listitem>
4013 <para>
4014 A string of the form <literal><parameter>n</parameter>$</literal> where
4015 <parameter>n</parameter> is the index of the argument to print.
4016 Index 1 means the first argument after
4017 <parameter>formatstr</parameter>. If the <parameter>position</parameter> is
4018 omitted, the default is to use the next argument in sequence.
4019 </para>
4020 </listitem>
4021 </varlistentry>
4023 <varlistentry>
4024 <term><parameter>flags</parameter> (optional)</term>
4025 <listitem>
4026 <para>
4027 Additional options controlling how the format specifier's output is
4028 formatted. Currently the only supported flag is a minus sign
4029 (<literal>-</literal>) which will cause the format specifier's output to be
4030 left-justified. This has no effect unless the <parameter>width</parameter>
4031 field is also specified.
4032 </para>
4033 </listitem>
4034 </varlistentry>
4036 <varlistentry>
4037 <term><parameter>width</parameter> (optional)</term>
4038 <listitem>
4039 <para>
4040 Specifies the <emphasis>minimum</emphasis> number of characters to use to
4041 display the format specifier's output. The output is padded on the
4042 left or right (depending on the <literal>-</literal> flag) with spaces as
4043 needed to fill the width. A too-small width does not cause
4044 truncation of the output, but is simply ignored. The width may be
4045 specified using any of the following: a positive integer; an
4046 asterisk (<literal>*</literal>) to use the next function argument as the
4047 width; or a string of the form <literal>*<parameter>n</parameter>$</literal> to
4048 use the <parameter>n</parameter>th function argument as the width.
4049 </para>
4051 <para>
4052 If the width comes from a function argument, that argument is
4053 consumed before the argument that is used for the format specifier's
4054 value. If the width argument is negative, the result is left
4055 aligned (as if the <literal>-</literal> flag had been specified) within a
4056 field of length <function>abs</function>(<parameter>width</parameter>).
4057 </para>
4058 </listitem>
4059 </varlistentry>
4061 <varlistentry>
4062 <term><parameter>type</parameter> (required)</term>
4063 <listitem>
4064 <para>
4065 The type of format conversion to use to produce the format
4066 specifier's output. The following types are supported:
4067 <itemizedlist>
4068 <listitem>
4069 <para>
4070 <literal>s</literal> formats the argument value as a simple
4071 string. A null value is treated as an empty string.
4072 </para>
4073 </listitem>
4074 <listitem>
4075 <para>
4076 <literal>I</literal> treats the argument value as an SQL
4077 identifier, double-quoting it if necessary.
4078 It is an error for the value to be null (equivalent to
4079 <function>quote_ident</function>).
4080 </para>
4081 </listitem>
4082 <listitem>
4083 <para>
4084 <literal>L</literal> quotes the argument value as an SQL literal.
4085 A null value is displayed as the string <literal>NULL</literal>, without
4086 quotes (equivalent to <function>quote_nullable</function>).
4087 </para>
4088 </listitem>
4089 </itemizedlist>
4090 </para>
4091 </listitem>
4092 </varlistentry>
4093 </variablelist>
4094 </para>
4096 <para>
4097 In addition to the format specifiers described above, the special sequence
4098 <literal>%%</literal> may be used to output a literal <literal>%</literal> character.
4099 </para>
4101 <para>
4102 Here are some examples of the basic format conversions:
4104 <screen>
4105 SELECT format('Hello %s', 'World');
4106 <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
4108 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
4109 <lineannotation>Result: </lineannotation><computeroutput>Testing one, two, three, %</computeroutput>
4111 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
4112 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
4114 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
4115 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')</computeroutput>
4116 </screen>
4117 </para>
4119 <para>
4120 Here are examples using <parameter>width</parameter> fields
4121 and the <literal>-</literal> flag:
4123 <screen>
4124 SELECT format('|%10s|', 'foo');
4125 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4127 SELECT format('|%-10s|', 'foo');
4128 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4130 SELECT format('|%*s|', 10, 'foo');
4131 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4133 SELECT format('|%*s|', -10, 'foo');
4134 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4136 SELECT format('|%-*s|', 10, 'foo');
4137 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4139 SELECT format('|%-*s|', -10, 'foo');
4140 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
4141 </screen>
4142 </para>
4144 <para>
4145 These examples show use of <parameter>position</parameter> fields:
4147 <screen>
4148 SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
4149 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, one</computeroutput>
4151 SELECT format('|%*2$s|', 'foo', 10, 'bar');
4152 <lineannotation>Result: </lineannotation><computeroutput>| bar|</computeroutput>
4154 SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
4155 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
4156 </screen>
4157 </para>
4159 <para>
4160 Unlike the standard C function <function>sprintf</function>,
4161 <productname>PostgreSQL</productname>'s <function>format</function> function allows format
4162 specifiers with and without <parameter>position</parameter> fields to be mixed
4163 in the same format string. A format specifier without a
4164 <parameter>position</parameter> field always uses the next argument after the
4165 last argument consumed.
4166 In addition, the <function>format</function> function does not require all
4167 function arguments to be used in the format string.
4168 For example:
4170 <screen>
4171 SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
4172 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, three</computeroutput>
4173 </screen>
4174 </para>
4176 <para>
4177 The <literal>%I</literal> and <literal>%L</literal> format specifiers are particularly
4178 useful for safely constructing dynamic SQL statements. See
4179 <xref linkend="plpgsql-quote-literal-example"/>.
4180 </para>
4181 </sect2>
4183 </sect1>
4186 <sect1 id="functions-binarystring">
4187 <title>Binary String Functions and Operators</title>
4189 <indexterm zone="functions-binarystring">
4190 <primary>binary data</primary>
4191 <secondary>functions</secondary>
4192 </indexterm>
4194 <para>
4195 This section describes functions and operators for examining and
4196 manipulating binary strings, that is values of type <type>bytea</type>.
4197 Many of these are equivalent, in purpose and syntax, to the
4198 text-string functions described in the previous section.
4199 </para>
4201 <para>
4202 <acronym>SQL</acronym> defines some string functions that use
4203 key words, rather than commas, to separate
4204 arguments. Details are in
4205 <xref linkend="functions-binarystring-sql"/>.
4206 <productname>PostgreSQL</productname> also provides versions of these functions
4207 that use the regular function invocation syntax
4208 (see <xref linkend="functions-binarystring-other"/>).
4209 </para>
4211 <table id="functions-binarystring-sql">
4212 <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
4213 <tgroup cols="1">
4214 <thead>
4215 <row>
4216 <entry role="func_table_entry"><para role="func_signature">
4217 Function/Operator
4218 </para>
4219 <para>
4220 Description
4221 </para>
4222 <para>
4223 Example(s)
4224 </para></entry>
4225 </row>
4226 </thead>
4228 <tbody>
4229 <row>
4230 <entry role="func_table_entry"><para role="func_signature">
4231 <indexterm>
4232 <primary>binary string</primary>
4233 <secondary>concatenation</secondary>
4234 </indexterm>
4235 <type>bytea</type> <literal>||</literal> <type>bytea</type>
4236 <returnvalue>bytea</returnvalue>
4237 </para>
4238 <para>
4239 Concatenates the two binary strings.
4240 </para>
4241 <para>
4242 <literal>'\x123456'::bytea || '\x789a00bcde'::bytea</literal>
4243 <returnvalue>\x123456789a00bcde</returnvalue>
4244 </para></entry>
4245 </row>
4247 <row>
4248 <entry role="func_table_entry"><para role="func_signature">
4249 <indexterm>
4250 <primary>bit_length</primary>
4251 </indexterm>
4252 <function>bit_length</function> ( <type>bytea</type> )
4253 <returnvalue>integer</returnvalue>
4254 </para>
4255 <para>
4256 Returns number of bits in the binary string (8
4257 times the <function>octet_length</function>).
4258 </para>
4259 <para>
4260 <literal>bit_length('\x123456'::bytea)</literal>
4261 <returnvalue>24</returnvalue>
4262 </para></entry>
4263 </row>
4265 <row>
4266 <entry role="func_table_entry"><para role="func_signature">
4267 <indexterm>
4268 <primary>btrim</primary>
4269 </indexterm>
4270 <function>btrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4271 <parameter>bytesremoved</parameter> <type>bytea</type> )
4272 <returnvalue>bytea</returnvalue>
4273 </para>
4274 <para>
4275 Removes the longest string containing only bytes appearing in
4276 <parameter>bytesremoved</parameter> from the start and end of
4277 <parameter>bytes</parameter>.
4278 </para>
4279 <para>
4280 <literal>btrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4281 <returnvalue>\x345678</returnvalue>
4282 </para></entry>
4283 </row>
4285 <row>
4286 <entry role="func_table_entry"><para role="func_signature">
4287 <indexterm>
4288 <primary>ltrim</primary>
4289 </indexterm>
4290 <function>ltrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4291 <parameter>bytesremoved</parameter> <type>bytea</type> )
4292 <returnvalue>bytea</returnvalue>
4293 </para>
4294 <para>
4295 Removes the longest string containing only bytes appearing in
4296 <parameter>bytesremoved</parameter> from the start of
4297 <parameter>bytes</parameter>.
4298 </para>
4299 <para>
4300 <literal>ltrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4301 <returnvalue>\x34567890</returnvalue>
4302 </para></entry>
4303 </row>
4305 <row>
4306 <entry role="func_table_entry"><para role="func_signature">
4307 <indexterm>
4308 <primary>octet_length</primary>
4309 </indexterm>
4310 <function>octet_length</function> ( <type>bytea</type> )
4311 <returnvalue>integer</returnvalue>
4312 </para>
4313 <para>
4314 Returns number of bytes in the binary string.
4315 </para>
4316 <para>
4317 <literal>octet_length('\x123456'::bytea)</literal>
4318 <returnvalue>3</returnvalue>
4319 </para></entry>
4320 </row>
4322 <row>
4323 <entry role="func_table_entry"><para role="func_signature">
4324 <indexterm>
4325 <primary>overlay</primary>
4326 </indexterm>
4327 <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> )
4328 <returnvalue>bytea</returnvalue>
4329 </para>
4330 <para>
4331 Replaces the substring of <parameter>bytes</parameter> that starts at
4332 the <parameter>start</parameter>'th byte and extends
4333 for <parameter>count</parameter> bytes
4334 with <parameter>newsubstring</parameter>.
4335 If <parameter>count</parameter> is omitted, it defaults to the length
4336 of <parameter>newsubstring</parameter>.
4337 </para>
4338 <para>
4339 <literal>overlay('\x1234567890'::bytea placing '\002\003'::bytea from 2 for 3)</literal>
4340 <returnvalue>\x12020390</returnvalue>
4341 </para></entry>
4342 </row>
4344 <row>
4345 <entry role="func_table_entry"><para role="func_signature">
4346 <indexterm>
4347 <primary>position</primary>
4348 </indexterm>
4349 <function>position</function> ( <parameter>substring</parameter> <type>bytea</type> <literal>IN</literal> <parameter>bytes</parameter> <type>bytea</type> )
4350 <returnvalue>integer</returnvalue>
4351 </para>
4352 <para>
4353 Returns first starting index of the specified
4354 <parameter>substring</parameter> within
4355 <parameter>bytes</parameter>, or zero if it's not present.
4356 </para>
4357 <para>
4358 <literal>position('\x5678'::bytea in '\x1234567890'::bytea)</literal>
4359 <returnvalue>3</returnvalue>
4360 </para></entry>
4361 </row>
4363 <row>
4364 <entry role="func_table_entry"><para role="func_signature">
4365 <indexterm>
4366 <primary>rtrim</primary>
4367 </indexterm>
4368 <function>rtrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4369 <parameter>bytesremoved</parameter> <type>bytea</type> )
4370 <returnvalue>bytea</returnvalue>
4371 </para>
4372 <para>
4373 Removes the longest string containing only bytes appearing in
4374 <parameter>bytesremoved</parameter> from the end of
4375 <parameter>bytes</parameter>.
4376 </para>
4377 <para>
4378 <literal>rtrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4379 <returnvalue>\x12345678</returnvalue>
4380 </para></entry>
4381 </row>
4383 <row>
4384 <entry role="func_table_entry"><para role="func_signature">
4385 <indexterm>
4386 <primary>substring</primary>
4387 </indexterm>
4388 <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> )
4389 <returnvalue>bytea</returnvalue>
4390 </para>
4391 <para>
4392 Extracts the substring of <parameter>bytes</parameter> starting at
4393 the <parameter>start</parameter>'th byte if that is specified,
4394 and stopping after <parameter>count</parameter> bytes if that is
4395 specified. Provide at least one of <parameter>start</parameter>
4396 and <parameter>count</parameter>.
4397 </para>
4398 <para>
4399 <literal>substring('\x1234567890'::bytea from 3 for 2)</literal>
4400 <returnvalue>\x5678</returnvalue>
4401 </para></entry>
4402 </row>
4404 <row>
4405 <entry role="func_table_entry"><para role="func_signature">
4406 <indexterm>
4407 <primary>trim</primary>
4408 </indexterm>
4409 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
4410 <parameter>bytesremoved</parameter> <type>bytea</type> <literal>FROM</literal>
4411 <parameter>bytes</parameter> <type>bytea</type> )
4412 <returnvalue>bytea</returnvalue>
4413 </para>
4414 <para>
4415 Removes the longest string containing only bytes appearing in
4416 <parameter>bytesremoved</parameter> from the start,
4417 end, or both ends (<literal>BOTH</literal> is the default)
4418 of <parameter>bytes</parameter>.
4419 </para>
4420 <para>
4421 <literal>trim('\x9012'::bytea from '\x1234567890'::bytea)</literal>
4422 <returnvalue>\x345678</returnvalue>
4423 </para></entry>
4424 </row>
4426 <row>
4427 <entry role="func_table_entry"><para role="func_signature">
4428 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
4429 <parameter>bytes</parameter> <type>bytea</type>,
4430 <parameter>bytesremoved</parameter> <type>bytea</type> )
4431 <returnvalue>bytea</returnvalue>
4432 </para>
4433 <para>
4434 This is a non-standard syntax for <function>trim()</function>.
4435 </para>
4436 <para>
4437 <literal>trim(both from '\x1234567890'::bytea, '\x9012'::bytea)</literal>
4438 <returnvalue>\x345678</returnvalue>
4439 </para></entry>
4440 </row>
4441 </tbody>
4442 </tgroup>
4443 </table>
4445 <para>
4446 Additional binary string manipulation functions are available and
4447 are listed in <xref linkend="functions-binarystring-other"/>. Some
4448 of them are used internally to implement the
4449 <acronym>SQL</acronym>-standard string functions listed in <xref
4450 linkend="functions-binarystring-sql"/>.
4451 </para>
4453 <table id="functions-binarystring-other">
4454 <title>Other Binary String Functions</title>
4455 <tgroup cols="1">
4456 <thead>
4457 <row>
4458 <entry role="func_table_entry"><para role="func_signature">
4459 Function
4460 </para>
4461 <para>
4462 Description
4463 </para>
4464 <para>
4465 Example(s)
4466 </para></entry>
4467 </row>
4468 </thead>
4470 <tbody>
4471 <row>
4472 <entry role="func_table_entry"><para role="func_signature">
4473 <indexterm>
4474 <primary>bit_count</primary>
4475 </indexterm>
4476 <indexterm>
4477 <primary>popcount</primary>
4478 <see>bit_count</see>
4479 </indexterm>
4480 <function>bit_count</function> ( <parameter>bytes</parameter> <type>bytea</type> )
4481 <returnvalue>bigint</returnvalue>
4482 </para>
4483 <para>
4484 Returns the number of bits set in the binary string (also known as
4485 <quote>popcount</quote>).
4486 </para>
4487 <para>
4488 <literal>bit_count('\x1234567890'::bytea)</literal>
4489 <returnvalue>15</returnvalue>
4490 </para></entry>
4491 </row>
4493 <row>
4494 <entry role="func_table_entry"><para role="func_signature">
4495 <indexterm>
4496 <primary>crc32</primary>
4497 </indexterm>
4498 <function>crc32</function> ( <type>bytea</type> )
4499 <returnvalue>bigint</returnvalue>
4500 </para>
4501 <para>
4502 Computes the CRC-32 value of the binary string.
4503 </para>
4504 <para>
4505 <literal>crc32('abc'::bytea)</literal>
4506 <returnvalue>891568578</returnvalue>
4507 </para></entry>
4508 </row>
4510 <row>
4511 <entry role="func_table_entry"><para role="func_signature">
4512 <indexterm>
4513 <primary>crc32c</primary>
4514 </indexterm>
4515 <function>crc32c</function> ( <type>bytea</type> )
4516 <returnvalue>bigint</returnvalue>
4517 </para>
4518 <para>
4519 Computes the CRC-32C value of the binary string.
4520 </para>
4521 <para>
4522 <literal>crc32c('abc'::bytea)</literal>
4523 <returnvalue>910901175</returnvalue>
4524 </para></entry>
4525 </row>
4527 <row>
4528 <entry role="func_table_entry"><para role="func_signature">
4529 <indexterm>
4530 <primary>get_bit</primary>
4531 </indexterm>
4532 <function>get_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4533 <parameter>n</parameter> <type>bigint</type> )
4534 <returnvalue>integer</returnvalue>
4535 </para>
4536 <para>
4537 Extracts <link linkend="functions-zerobased-note">n'th</link> bit
4538 from binary string.
4539 </para>
4540 <para>
4541 <literal>get_bit('\x1234567890'::bytea, 30)</literal>
4542 <returnvalue>1</returnvalue>
4543 </para></entry>
4544 </row>
4546 <row>
4547 <entry role="func_table_entry"><para role="func_signature">
4548 <indexterm>
4549 <primary>get_byte</primary>
4550 </indexterm>
4551 <function>get_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4552 <parameter>n</parameter> <type>integer</type> )
4553 <returnvalue>integer</returnvalue>
4554 </para>
4555 <para>
4556 Extracts <link linkend="functions-zerobased-note">n'th</link> byte
4557 from binary string.
4558 </para>
4559 <para>
4560 <literal>get_byte('\x1234567890'::bytea, 4)</literal>
4561 <returnvalue>144</returnvalue>
4562 </para></entry>
4563 </row>
4565 <row>
4566 <entry role="func_table_entry"><para role="func_signature">
4567 <indexterm>
4568 <primary>length</primary>
4569 </indexterm>
4570 <indexterm>
4571 <primary>binary string</primary>
4572 <secondary>length</secondary>
4573 </indexterm>
4574 <indexterm>
4575 <primary>length</primary>
4576 <secondary sortas="binary string">of a binary string</secondary>
4577 <see>binary strings, length</see>
4578 </indexterm>
4579 <function>length</function> ( <type>bytea</type> )
4580 <returnvalue>integer</returnvalue>
4581 </para>
4582 <para>
4583 Returns the number of bytes in the binary string.
4584 </para>
4585 <para>
4586 <literal>length('\x1234567890'::bytea)</literal>
4587 <returnvalue>5</returnvalue>
4588 </para></entry>
4589 </row>
4591 <row>
4592 <entry role="func_table_entry"><para role="func_signature">
4593 <function>length</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4594 <parameter>encoding</parameter> <type>name</type> )
4595 <returnvalue>integer</returnvalue>
4596 </para>
4597 <para>
4598 Returns the number of characters in the binary string, assuming
4599 that it is text in the given <parameter>encoding</parameter>.
4600 </para>
4601 <para>
4602 <literal>length('jose'::bytea, 'UTF8')</literal>
4603 <returnvalue>4</returnvalue>
4604 </para></entry>
4605 </row>
4607 <row>
4608 <entry role="func_table_entry"><para role="func_signature">
4609 <indexterm>
4610 <primary>md5</primary>
4611 </indexterm>
4612 <function>md5</function> ( <type>bytea</type> )
4613 <returnvalue>text</returnvalue>
4614 </para>
4615 <para>
4616 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
4617 the binary string, with the result written in hexadecimal.
4618 </para>
4619 <para>
4620 <literal>md5('Th\000omas'::bytea)</literal>
4621 <returnvalue>8ab2d3c9689aaf18&zwsp;b4958c334c82d8b1</returnvalue>
4622 </para></entry>
4623 </row>
4625 <row>
4626 <entry role="func_table_entry"><para role="func_signature">
4627 <indexterm>
4628 <primary>set_bit</primary>
4629 </indexterm>
4630 <function>set_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4631 <parameter>n</parameter> <type>bigint</type>,
4632 <parameter>newvalue</parameter> <type>integer</type> )
4633 <returnvalue>bytea</returnvalue>
4634 </para>
4635 <para>
4636 Sets <link linkend="functions-zerobased-note">n'th</link> bit in
4637 binary string to <parameter>newvalue</parameter>.
4638 </para>
4639 <para>
4640 <literal>set_bit('\x1234567890'::bytea, 30, 0)</literal>
4641 <returnvalue>\x1234563890</returnvalue>
4642 </para></entry>
4643 </row>
4645 <row>
4646 <entry role="func_table_entry"><para role="func_signature">
4647 <indexterm>
4648 <primary>set_byte</primary>
4649 </indexterm>
4650 <function>set_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4651 <parameter>n</parameter> <type>integer</type>,
4652 <parameter>newvalue</parameter> <type>integer</type> )
4653 <returnvalue>bytea</returnvalue>
4654 </para>
4655 <para>
4656 Sets <link linkend="functions-zerobased-note">n'th</link> byte in
4657 binary string to <parameter>newvalue</parameter>.
4658 </para>
4659 <para>
4660 <literal>set_byte('\x1234567890'::bytea, 4, 64)</literal>
4661 <returnvalue>\x1234567840</returnvalue>
4662 </para></entry>
4663 </row>
4665 <row>
4666 <entry role="func_table_entry"><para role="func_signature">
4667 <indexterm>
4668 <primary>sha224</primary>
4669 </indexterm>
4670 <function>sha224</function> ( <type>bytea</type> )
4671 <returnvalue>bytea</returnvalue>
4672 </para>
4673 <para>
4674 Computes the SHA-224 <link linkend="functions-hash-note">hash</link>
4675 of the binary string.
4676 </para>
4677 <para>
4678 <literal>sha224('abc'::bytea)</literal>
4679 <returnvalue>\x23097d223405d8228642a477bda2&zwsp;55b32aadbce4bda0b3f7e36c9da7</returnvalue>
4680 </para></entry>
4681 </row>
4683 <row>
4684 <entry role="func_table_entry"><para role="func_signature">
4685 <indexterm>
4686 <primary>sha256</primary>
4687 </indexterm>
4688 <function>sha256</function> ( <type>bytea</type> )
4689 <returnvalue>bytea</returnvalue>
4690 </para>
4691 <para>
4692 Computes the SHA-256 <link linkend="functions-hash-note">hash</link>
4693 of the binary string.
4694 </para>
4695 <para>
4696 <literal>sha256('abc'::bytea)</literal>
4697 <returnvalue>\xba7816bf8f01cfea414140de5dae2223&zwsp;b00361a396177a9cb410ff61f20015ad</returnvalue>
4698 </para></entry>
4699 </row>
4701 <row>
4702 <entry role="func_table_entry"><para role="func_signature">
4703 <indexterm>
4704 <primary>sha384</primary>
4705 </indexterm>
4706 <function>sha384</function> ( <type>bytea</type> )
4707 <returnvalue>bytea</returnvalue>
4708 </para>
4709 <para>
4710 Computes the SHA-384 <link linkend="functions-hash-note">hash</link>
4711 of the binary string.
4712 </para>
4713 <para>
4714 <literal>sha384('abc'::bytea)</literal>
4715 <returnvalue>\xcb00753f45a35e8bb5a03d699ac65007&zwsp;272c32ab0eded1631a8b605a43ff5bed&zwsp;8086072ba1e7cc2358baeca134c825a7</returnvalue>
4716 </para></entry>
4717 </row>
4719 <row>
4720 <entry role="func_table_entry"><para role="func_signature">
4721 <indexterm>
4722 <primary>sha512</primary>
4723 </indexterm>
4724 <function>sha512</function> ( <type>bytea</type> )
4725 <returnvalue>bytea</returnvalue>
4726 </para>
4727 <para>
4728 Computes the SHA-512 <link linkend="functions-hash-note">hash</link>
4729 of the binary string.
4730 </para>
4731 <para>
4732 <literal>sha512('abc'::bytea)</literal>
4733 <returnvalue>\xddaf35a193617abacc417349ae204131&zwsp;12e6fa4e89a97ea20a9eeee64b55d39a&zwsp;2192992a274fc1a836ba3c23a3feebbd&zwsp;454d4423643ce80e2a9ac94fa54ca49f</returnvalue>
4734 </para></entry>
4735 </row>
4737 <row>
4738 <entry role="func_table_entry"><para role="func_signature">
4739 <indexterm>
4740 <primary>substr</primary>
4741 </indexterm>
4742 <function>substr</function> ( <parameter>bytes</parameter> <type>bytea</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
4743 <returnvalue>bytea</returnvalue>
4744 </para>
4745 <para>
4746 Extracts the substring of <parameter>bytes</parameter> starting at
4747 the <parameter>start</parameter>'th byte,
4748 and extending for <parameter>count</parameter> bytes if that is
4749 specified. (Same
4750 as <literal>substring(<parameter>bytes</parameter>
4751 from <parameter>start</parameter>
4752 for <parameter>count</parameter>)</literal>.)
4753 </para>
4754 <para>
4755 <literal>substr('\x1234567890'::bytea, 3, 2)</literal>
4756 <returnvalue>\x5678</returnvalue>
4757 </para></entry>
4758 </row>
4759 </tbody>
4760 </tgroup>
4761 </table>
4763 <para id="functions-zerobased-note">
4764 Functions <function>get_byte</function> and <function>set_byte</function>
4765 number the first byte of a binary string as byte 0.
4766 Functions <function>get_bit</function> and <function>set_bit</function>
4767 number bits from the right within each byte; for example bit 0 is the least
4768 significant bit of the first byte, and bit 15 is the most significant bit
4769 of the second byte.
4770 </para>
4772 <para id="functions-hash-note">
4773 For historical reasons, the function <function>md5</function>
4774 returns a hex-encoded value of type <type>text</type> whereas the SHA-2
4775 functions return type <type>bytea</type>. Use the functions
4776 <link linkend="function-encode"><function>encode</function></link>
4777 and <link linkend="function-decode"><function>decode</function></link> to
4778 convert between the two. For example write <literal>encode(sha256('abc'),
4779 'hex')</literal> to get a hex-encoded text representation,
4780 or <literal>decode(md5('abc'), 'hex')</literal> to get
4781 a <type>bytea</type> value.
4782 </para>
4784 <para>
4785 <indexterm>
4786 <primary>character string</primary>
4787 <secondary>converting to binary string</secondary>
4788 </indexterm>
4789 <indexterm>
4790 <primary>binary string</primary>
4791 <secondary>converting to character string</secondary>
4792 </indexterm>
4793 Functions for converting strings between different character sets
4794 (encodings), and for representing arbitrary binary data in textual
4795 form, are shown in
4796 <xref linkend="functions-binarystring-conversions"/>. For these
4797 functions, an argument or result of type <type>text</type> is expressed
4798 in the database's default encoding, while arguments or results of
4799 type <type>bytea</type> are in an encoding named by another argument.
4800 </para>
4802 <table id="functions-binarystring-conversions">
4803 <title>Text/Binary String Conversion Functions</title>
4804 <tgroup cols="1">
4805 <thead>
4806 <row>
4807 <entry role="func_table_entry"><para role="func_signature">
4808 Function
4809 </para>
4810 <para>
4811 Description
4812 </para>
4813 <para>
4814 Example(s)
4815 </para></entry>
4816 </row>
4817 </thead>
4819 <tbody>
4820 <row>
4821 <entry role="func_table_entry"><para role="func_signature">
4822 <indexterm>
4823 <primary>convert</primary>
4824 </indexterm>
4825 <function>convert</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4826 <parameter>src_encoding</parameter> <type>name</type>,
4827 <parameter>dest_encoding</parameter> <type>name</type> )
4828 <returnvalue>bytea</returnvalue>
4829 </para>
4830 <para>
4831 Converts a binary string representing text in
4832 encoding <parameter>src_encoding</parameter>
4833 to a binary string in encoding <parameter>dest_encoding</parameter>
4834 (see <xref linkend="multibyte-conversions-supported"/> for
4835 available conversions).
4836 </para>
4837 <para>
4838 <literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal>
4839 <returnvalue>\x746578745f696e5f75746638</returnvalue>
4840 </para></entry>
4841 </row>
4843 <row>
4844 <entry role="func_table_entry"><para role="func_signature">
4845 <indexterm>
4846 <primary>convert_from</primary>
4847 </indexterm>
4848 <function>convert_from</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4849 <parameter>src_encoding</parameter> <type>name</type> )
4850 <returnvalue>text</returnvalue>
4851 </para>
4852 <para>
4853 Converts a binary string representing text in
4854 encoding <parameter>src_encoding</parameter>
4855 to <type>text</type> in the database encoding
4856 (see <xref linkend="multibyte-conversions-supported"/> for
4857 available conversions).
4858 </para>
4859 <para>
4860 <literal>convert_from('text_in_utf8', 'UTF8')</literal>
4861 <returnvalue>text_in_utf8</returnvalue>
4862 </para></entry>
4863 </row>
4865 <row>
4866 <entry role="func_table_entry"><para role="func_signature">
4867 <indexterm>
4868 <primary>convert_to</primary>
4869 </indexterm>
4870 <function>convert_to</function> ( <parameter>string</parameter> <type>text</type>,
4871 <parameter>dest_encoding</parameter> <type>name</type> )
4872 <returnvalue>bytea</returnvalue>
4873 </para>
4874 <para>
4875 Converts a <type>text</type> string (in the database encoding) to a
4876 binary string encoded in encoding <parameter>dest_encoding</parameter>
4877 (see <xref linkend="multibyte-conversions-supported"/> for
4878 available conversions).
4879 </para>
4880 <para>
4881 <literal>convert_to('some_text', 'UTF8')</literal>
4882 <returnvalue>\x736f6d655f74657874</returnvalue>
4883 </para></entry>
4884 </row>
4886 <row>
4887 <entry role="func_table_entry"><para role="func_signature">
4888 <indexterm id="function-encode">
4889 <primary>encode</primary>
4890 </indexterm>
4891 <function>encode</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4892 <parameter>format</parameter> <type>text</type> )
4893 <returnvalue>text</returnvalue>
4894 </para>
4895 <para>
4896 Encodes binary data into a textual representation; supported
4897 <parameter>format</parameter> values are:
4898 <link linkend="encode-format-base64"><literal>base64</literal></link>,
4899 <link linkend="encode-format-escape"><literal>escape</literal></link>,
4900 <link linkend="encode-format-hex"><literal>hex</literal></link>.
4901 </para>
4902 <para>
4903 <literal>encode('123\000\001', 'base64')</literal>
4904 <returnvalue>MTIzAAE=</returnvalue>
4905 </para></entry>
4906 </row>
4908 <row>
4909 <entry role="func_table_entry"><para role="func_signature">
4910 <indexterm id="function-decode">
4911 <primary>decode</primary>
4912 </indexterm>
4913 <function>decode</function> ( <parameter>string</parameter> <type>text</type>,
4914 <parameter>format</parameter> <type>text</type> )
4915 <returnvalue>bytea</returnvalue>
4916 </para>
4917 <para>
4918 Decodes binary data from a textual representation; supported
4919 <parameter>format</parameter> values are the same as
4920 for <function>encode</function>.
4921 </para>
4922 <para>
4923 <literal>decode('MTIzAAE=', 'base64')</literal>
4924 <returnvalue>\x3132330001</returnvalue>
4925 </para></entry>
4926 </row>
4927 </tbody>
4928 </tgroup>
4929 </table>
4931 <para>
4932 The <function>encode</function> and <function>decode</function>
4933 functions support the following textual formats:
4935 <variablelist>
4936 <varlistentry id="encode-format-base64">
4937 <term>base64
4938 <indexterm>
4939 <primary>base64 format</primary>
4940 </indexterm></term>
4941 <listitem>
4942 <para>
4943 The <literal>base64</literal> format is that
4944 of <ulink url="https://datatracker.ietf.org/doc/html/rfc2045#section-6.8">RFC
4945 2045 Section 6.8</ulink>. As per the <acronym>RFC</acronym>, encoded lines are
4946 broken at 76 characters. However instead of the MIME CRLF
4947 end-of-line marker, only a newline is used for end-of-line.
4948 The <function>decode</function> function ignores carriage-return,
4949 newline, space, and tab characters. Otherwise, an error is
4950 raised when <function>decode</function> is supplied invalid
4951 base64 data &mdash; including when trailing padding is incorrect.
4952 </para>
4953 </listitem>
4954 </varlistentry>
4956 <varlistentry id="encode-format-escape">
4957 <term>escape
4958 <indexterm>
4959 <primary>escape format</primary>
4960 </indexterm></term>
4961 <listitem>
4962 <para>
4963 The <literal>escape</literal> format converts zero bytes and
4964 bytes with the high bit set into octal escape sequences
4965 (<literal>\</literal><replaceable>nnn</replaceable>), and it doubles
4966 backslashes. Other byte values are represented literally.
4967 The <function>decode</function> function will raise an error if a
4968 backslash is not followed by either a second backslash or three
4969 octal digits; it accepts other byte values unchanged.
4970 </para>
4971 </listitem>
4972 </varlistentry>
4974 <varlistentry id="encode-format-hex">
4975 <term>hex
4976 <indexterm>
4977 <primary>hex format</primary>
4978 </indexterm></term>
4979 <listitem>
4980 <para>
4981 The <literal>hex</literal> format represents each 4 bits of
4982 data as one hexadecimal digit, <literal>0</literal>
4983 through <literal>f</literal>, writing the higher-order digit of
4984 each byte first. The <function>encode</function> function outputs
4985 the <literal>a</literal>-<literal>f</literal> hex digits in lower
4986 case. Because the smallest unit of data is 8 bits, there are
4987 always an even number of characters returned
4988 by <function>encode</function>.
4989 The <function>decode</function> function
4990 accepts the <literal>a</literal>-<literal>f</literal> characters in
4991 either upper or lower case. An error is raised
4992 when <function>decode</function> is given invalid hex data
4993 &mdash; including when given an odd number of characters.
4994 </para>
4995 </listitem>
4996 </varlistentry>
4997 </variablelist>
4998 </para>
5000 <para>
5001 See also the aggregate function <function>string_agg</function> in
5002 <xref linkend="functions-aggregate"/> and the large object functions
5003 in <xref linkend="lo-funcs"/>.
5004 </para>
5005 </sect1>
5008 <sect1 id="functions-bitstring">
5009 <title>Bit String Functions and Operators</title>
5011 <indexterm zone="functions-bitstring">
5012 <primary>bit strings</primary>
5013 <secondary>functions</secondary>
5014 </indexterm>
5016 <para>
5017 This section describes functions and operators for examining and
5018 manipulating bit strings, that is values of the types
5019 <type>bit</type> and <type>bit varying</type>. (While only
5020 type <type>bit</type> is mentioned in these tables, values of
5021 type <type>bit varying</type> can be used interchangeably.)
5022 Bit strings support the usual comparison operators shown in
5023 <xref linkend="functions-comparison-op-table"/>, as well as the
5024 operators shown in <xref linkend="functions-bit-string-op-table"/>.
5025 </para>
5027 <table id="functions-bit-string-op-table">
5028 <title>Bit String Operators</title>
5029 <tgroup cols="1">
5030 <thead>
5031 <row>
5032 <entry role="func_table_entry"><para role="func_signature">
5033 Operator
5034 </para>
5035 <para>
5036 Description
5037 </para>
5038 <para>
5039 Example(s)
5040 </para></entry>
5041 </row>
5042 </thead>
5044 <tbody>
5045 <row>
5046 <entry role="func_table_entry"><para role="func_signature">
5047 <type>bit</type> <literal>||</literal> <type>bit</type>
5048 <returnvalue>bit</returnvalue>
5049 </para>
5050 <para>
5051 Concatenation
5052 </para>
5053 <para>
5054 <literal>B'10001' || B'011'</literal>
5055 <returnvalue>10001011</returnvalue>
5056 </para></entry>
5057 </row>
5059 <row>
5060 <entry role="func_table_entry"><para role="func_signature">
5061 <type>bit</type> <literal>&amp;</literal> <type>bit</type>
5062 <returnvalue>bit</returnvalue>
5063 </para>
5064 <para>
5065 Bitwise AND (inputs must be of equal length)
5066 </para>
5067 <para>
5068 <literal>B'10001' &amp; B'01101'</literal>
5069 <returnvalue>00001</returnvalue>
5070 </para></entry>
5071 </row>
5073 <row>
5074 <entry role="func_table_entry"><para role="func_signature">
5075 <type>bit</type> <literal>|</literal> <type>bit</type>
5076 <returnvalue>bit</returnvalue>
5077 </para>
5078 <para>
5079 Bitwise OR (inputs must be of equal length)
5080 </para>
5081 <para>
5082 <literal>B'10001' | B'01101'</literal>
5083 <returnvalue>11101</returnvalue>
5084 </para></entry>
5085 </row>
5087 <row>
5088 <entry role="func_table_entry"><para role="func_signature">
5089 <type>bit</type> <literal>#</literal> <type>bit</type>
5090 <returnvalue>bit</returnvalue>
5091 </para>
5092 <para>
5093 Bitwise exclusive OR (inputs must be of equal length)
5094 </para>
5095 <para>
5096 <literal>B'10001' # B'01101'</literal>
5097 <returnvalue>11100</returnvalue>
5098 </para></entry>
5099 </row>
5101 <row>
5102 <entry role="func_table_entry"><para role="func_signature">
5103 <literal>~</literal> <type>bit</type>
5104 <returnvalue>bit</returnvalue>
5105 </para>
5106 <para>
5107 Bitwise NOT
5108 </para>
5109 <para>
5110 <literal>~ B'10001'</literal>
5111 <returnvalue>01110</returnvalue>
5112 </para></entry>
5113 </row>
5115 <row>
5116 <entry role="func_table_entry"><para role="func_signature">
5117 <type>bit</type> <literal>&lt;&lt;</literal> <type>integer</type>
5118 <returnvalue>bit</returnvalue>
5119 </para>
5120 <para>
5121 Bitwise shift left
5122 (string length is preserved)
5123 </para>
5124 <para>
5125 <literal>B'10001' &lt;&lt; 3</literal>
5126 <returnvalue>01000</returnvalue>
5127 </para></entry>
5128 </row>
5130 <row>
5131 <entry role="func_table_entry"><para role="func_signature">
5132 <type>bit</type> <literal>&gt;&gt;</literal> <type>integer</type>
5133 <returnvalue>bit</returnvalue>
5134 </para>
5135 <para>
5136 Bitwise shift right
5137 (string length is preserved)
5138 </para>
5139 <para>
5140 <literal>B'10001' &gt;&gt; 2</literal>
5141 <returnvalue>00100</returnvalue>
5142 </para></entry>
5143 </row>
5144 </tbody>
5145 </tgroup>
5146 </table>
5148 <para>
5149 Some of the functions available for binary strings are also available
5150 for bit strings, as shown in <xref linkend="functions-bit-string-table"/>.
5151 </para>
5153 <table id="functions-bit-string-table">
5154 <title>Bit String Functions</title>
5155 <tgroup cols="1">
5156 <thead>
5157 <row>
5158 <entry role="func_table_entry"><para role="func_signature">
5159 Function
5160 </para>
5161 <para>
5162 Description
5163 </para>
5164 <para>
5165 Example(s)
5166 </para></entry>
5167 </row>
5168 </thead>
5170 <tbody>
5171 <row>
5172 <entry role="func_table_entry"><para role="func_signature">
5173 <indexterm>
5174 <primary>bit_count</primary>
5175 </indexterm>
5176 <function>bit_count</function> ( <type>bit</type> )
5177 <returnvalue>bigint</returnvalue>
5178 </para>
5179 <para>
5180 Returns the number of bits set in the bit string (also known as
5181 <quote>popcount</quote>).
5182 </para>
5183 <para>
5184 <literal>bit_count(B'10111')</literal>
5185 <returnvalue>4</returnvalue>
5186 </para></entry>
5187 </row>
5189 <row>
5190 <entry role="func_table_entry"><para role="func_signature">
5191 <indexterm>
5192 <primary>bit_length</primary>
5193 </indexterm>
5194 <function>bit_length</function> ( <type>bit</type> )
5195 <returnvalue>integer</returnvalue>
5196 </para>
5197 <para>
5198 Returns number of bits in the bit string.
5199 </para>
5200 <para>
5201 <literal>bit_length(B'10111')</literal>
5202 <returnvalue>5</returnvalue>
5203 </para></entry>
5204 </row>
5206 <row>
5207 <entry role="func_table_entry"><para role="func_signature">
5208 <indexterm>
5209 <primary>length</primary>
5210 </indexterm>
5211 <indexterm>
5212 <primary>bit string</primary>
5213 <secondary>length</secondary>
5214 </indexterm>
5215 <function>length</function> ( <type>bit</type> )
5216 <returnvalue>integer</returnvalue>
5217 </para>
5218 <para>
5219 Returns number of bits in the bit string.
5220 </para>
5221 <para>
5222 <literal>length(B'10111')</literal>
5223 <returnvalue>5</returnvalue>
5224 </para></entry>
5225 </row>
5227 <row>
5228 <entry role="func_table_entry"><para role="func_signature">
5229 <indexterm>
5230 <primary>octet_length</primary>
5231 </indexterm>
5232 <function>octet_length</function> ( <type>bit</type> )
5233 <returnvalue>integer</returnvalue>
5234 </para>
5235 <para>
5236 Returns number of bytes in the bit string.
5237 </para>
5238 <para>
5239 <literal>octet_length(B'1011111011')</literal>
5240 <returnvalue>2</returnvalue>
5241 </para></entry>
5242 </row>
5244 <row>
5245 <entry role="func_table_entry"><para role="func_signature">
5246 <indexterm>
5247 <primary>overlay</primary>
5248 </indexterm>
5249 <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> )
5250 <returnvalue>bit</returnvalue>
5251 </para>
5252 <para>
5253 Replaces the substring of <parameter>bits</parameter> that starts at
5254 the <parameter>start</parameter>'th bit and extends
5255 for <parameter>count</parameter> bits
5256 with <parameter>newsubstring</parameter>.
5257 If <parameter>count</parameter> is omitted, it defaults to the length
5258 of <parameter>newsubstring</parameter>.
5259 </para>
5260 <para>
5261 <literal>overlay(B'01010101010101010' placing B'11111' from 2 for 3)</literal>
5262 <returnvalue>0111110101010101010</returnvalue>
5263 </para></entry>
5264 </row>
5266 <row>
5267 <entry role="func_table_entry"><para role="func_signature">
5268 <indexterm>
5269 <primary>position</primary>
5270 </indexterm>
5271 <function>position</function> ( <parameter>substring</parameter> <type>bit</type> <literal>IN</literal> <parameter>bits</parameter> <type>bit</type> )
5272 <returnvalue>integer</returnvalue>
5273 </para>
5274 <para>
5275 Returns first starting index of the specified <parameter>substring</parameter>
5276 within <parameter>bits</parameter>, or zero if it's not present.
5277 </para>
5278 <para>
5279 <literal>position(B'010' in B'000001101011')</literal>
5280 <returnvalue>8</returnvalue>
5281 </para></entry>
5282 </row>
5284 <row>
5285 <entry role="func_table_entry"><para role="func_signature">
5286 <indexterm>
5287 <primary>substring</primary>
5288 </indexterm>
5289 <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> )
5290 <returnvalue>bit</returnvalue>
5291 </para>
5292 <para>
5293 Extracts the substring of <parameter>bits</parameter> starting at
5294 the <parameter>start</parameter>'th bit if that is specified,
5295 and stopping after <parameter>count</parameter> bits if that is
5296 specified. Provide at least one of <parameter>start</parameter>
5297 and <parameter>count</parameter>.
5298 </para>
5299 <para>
5300 <literal>substring(B'110010111111' from 3 for 2)</literal>
5301 <returnvalue>00</returnvalue>
5302 </para></entry>
5303 </row>
5305 <row>
5306 <entry role="func_table_entry"><para role="func_signature">
5307 <indexterm>
5308 <primary>get_bit</primary>
5309 </indexterm>
5310 <function>get_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5311 <parameter>n</parameter> <type>integer</type> )
5312 <returnvalue>integer</returnvalue>
5313 </para>
5314 <para>
5315 Extracts <parameter>n</parameter>'th bit
5316 from bit string; the first (leftmost) bit is bit 0.
5317 </para>
5318 <para>
5319 <literal>get_bit(B'101010101010101010', 6)</literal>
5320 <returnvalue>1</returnvalue>
5321 </para></entry>
5322 </row>
5324 <row>
5325 <entry role="func_table_entry"><para role="func_signature">
5326 <indexterm>
5327 <primary>set_bit</primary>
5328 </indexterm>
5329 <function>set_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5330 <parameter>n</parameter> <type>integer</type>,
5331 <parameter>newvalue</parameter> <type>integer</type> )
5332 <returnvalue>bit</returnvalue>
5333 </para>
5334 <para>
5335 Sets <parameter>n</parameter>'th bit in
5336 bit string to <parameter>newvalue</parameter>;
5337 the first (leftmost) bit is bit 0.
5338 </para>
5339 <para>
5340 <literal>set_bit(B'101010101010101010', 6, 0)</literal>
5341 <returnvalue>101010001010101010</returnvalue>
5342 </para></entry>
5343 </row>
5344 </tbody>
5345 </tgroup>
5346 </table>
5348 <para>
5349 In addition, it is possible to cast integral values to and from type
5350 <type>bit</type>.
5351 Casting an integer to <type>bit(n)</type> copies the rightmost
5352 <literal>n</literal> bits. Casting an integer to a bit string width wider
5353 than the integer itself will sign-extend on the left.
5354 Some examples:
5355 <programlisting>
5356 44::bit(10) <lineannotation>0000101100</lineannotation>
5357 44::bit(3) <lineannotation>100</lineannotation>
5358 cast(-44 as bit(12)) <lineannotation>111111010100</lineannotation>
5359 '1110'::bit(4)::integer <lineannotation>14</lineannotation>
5360 </programlisting>
5361 Note that casting to just <quote>bit</quote> means casting to
5362 <literal>bit(1)</literal>, and so will deliver only the least significant
5363 bit of the integer.
5364 </para>
5365 </sect1>
5368 <sect1 id="functions-matching">
5369 <title>Pattern Matching</title>
5371 <indexterm zone="functions-matching">
5372 <primary>pattern matching</primary>
5373 </indexterm>
5375 <para>
5376 There are three separate approaches to pattern matching provided
5377 by <productname>PostgreSQL</productname>: the traditional
5378 <acronym>SQL</acronym> <function>LIKE</function> operator, the
5379 more recent <function>SIMILAR TO</function> operator (added in
5380 SQL:1999), and <acronym>POSIX</acronym>-style regular
5381 expressions. Aside from the basic <quote>does this string match
5382 this pattern?</quote> operators, functions are available to extract
5383 or replace matching substrings and to split a string at matching
5384 locations.
5385 </para>
5387 <tip>
5388 <para>
5389 If you have pattern matching needs that go beyond this,
5390 consider writing a user-defined function in Perl or Tcl.
5391 </para>
5392 </tip>
5394 <caution>
5395 <para>
5396 While most regular-expression searches can be executed very quickly,
5397 regular expressions can be contrived that take arbitrary amounts of
5398 time and memory to process. Be wary of accepting regular-expression
5399 search patterns from hostile sources. If you must do so, it is
5400 advisable to impose a statement timeout.
5401 </para>
5403 <para>
5404 Searches using <function>SIMILAR TO</function> patterns have the same
5405 security hazards, since <function>SIMILAR TO</function> provides many
5406 of the same capabilities as <acronym>POSIX</acronym>-style regular
5407 expressions.
5408 </para>
5410 <para>
5411 <function>LIKE</function> searches, being much simpler than the other
5412 two options, are safer to use with possibly-hostile pattern sources.
5413 </para>
5414 </caution>
5416 <para>
5417 <function>SIMILAR TO</function> and <acronym>POSIX</acronym>-style regular
5418 expressions do not support nondeterministic collations. If required, use
5419 <function>LIKE</function> or apply a different collation to the expression
5420 to work around this limitation.
5421 </para>
5423 <sect2 id="functions-like">
5424 <title><function>LIKE</function></title>
5426 <indexterm>
5427 <primary>LIKE</primary>
5428 </indexterm>
5430 <synopsis>
5431 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5432 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5433 </synopsis>
5435 <para>
5436 The <function>LIKE</function> expression returns true if the
5437 <replaceable>string</replaceable> matches the supplied
5438 <replaceable>pattern</replaceable>. (As
5439 expected, the <function>NOT LIKE</function> expression returns
5440 false if <function>LIKE</function> returns true, and vice versa.
5441 An equivalent expression is
5442 <literal>NOT (<replaceable>string</replaceable> LIKE
5443 <replaceable>pattern</replaceable>)</literal>.)
5444 </para>
5446 <para>
5447 If <replaceable>pattern</replaceable> does not contain percent
5448 signs or underscores, then the pattern only represents the string
5449 itself; in that case <function>LIKE</function> acts like the
5450 equals operator. An underscore (<literal>_</literal>) in
5451 <replaceable>pattern</replaceable> stands for (matches) any single
5452 character; a percent sign (<literal>%</literal>) matches any sequence
5453 of zero or more characters.
5454 </para>
5456 <para>
5457 Some examples:
5458 <programlisting>
5459 'abc' LIKE 'abc' <lineannotation>true</lineannotation>
5460 'abc' LIKE 'a%' <lineannotation>true</lineannotation>
5461 'abc' LIKE '_b_' <lineannotation>true</lineannotation>
5462 'abc' LIKE 'c' <lineannotation>false</lineannotation>
5463 </programlisting>
5464 </para>
5466 <para>
5467 <function>LIKE</function> pattern matching supports nondeterministic
5468 collations (see <xref linkend="collation-nondeterministic"/>), such as
5469 case-insensitive collations or collations that, say, ignore punctuation.
5470 So with a case-insensitive collation, one could have:
5471 <programlisting>
5472 'AbC' LIKE 'abc' COLLATE case_insensitive <lineannotation>true</lineannotation>
5473 'AbC' LIKE 'a%' COLLATE case_insensitive <lineannotation>true</lineannotation>
5474 </programlisting>
5475 With collations that ignore certain characters or in general that consider
5476 strings of different lengths equal, the semantics can become a bit more
5477 complicated. Consider these examples:
5478 <programlisting>
5479 '.foo.' LIKE 'foo' COLLATE ign_punct <lineannotation>true</lineannotation>
5480 '.foo.' LIKE 'f_o' COLLATE ign_punct <lineannotation>true</lineannotation>
5481 '.foo.' LIKE '_oo' COLLATE ign_punct <lineannotation>false</lineannotation>
5482 </programlisting>
5483 The way the matching works is that the pattern is partitioned into
5484 sequences of wildcards and non-wildcard strings (wildcards being
5485 <literal>_</literal> and <literal>%</literal>). For example, the pattern
5486 <literal>f_o</literal> is partitioned into <literal>f, _, o</literal>, the
5487 pattern <literal>_oo</literal> is partitioned into <literal>_,
5488 oo</literal>. The input string matches the pattern if it can be
5489 partitioned in such a way that the wildcards match one character or any
5490 number of characters respectively and the non-wildcard partitions are
5491 equal under the applicable collation. So for example, <literal>'.foo.'
5492 LIKE 'f_o' COLLATE ign_punct</literal> is true because one can partition
5493 <literal>.foo.</literal> into <literal>.f, o, o.</literal>, and then
5494 <literal>'.f' = 'f' COLLATE ign_punct</literal>, <literal>'o'</literal>
5495 matches the <literal>_</literal> wildcard, and <literal>'o.' = 'o' COLLATE
5496 ign_punct</literal>. But <literal>'.foo.' LIKE '_oo' COLLATE
5497 ign_punct</literal> is false because <literal>.foo.</literal> cannot be
5498 partitioned in a way that the first character is any character and the
5499 rest of the string compares equal to <literal>oo</literal>. (Note that
5500 the single-character wildcard always matches exactly one character,
5501 independent of the collation. So in this example, the
5502 <literal>_</literal> would match <literal>.</literal>, but then the rest
5503 of the input string won't match the rest of the pattern.)
5504 </para>
5506 <para>
5507 <function>LIKE</function> pattern matching always covers the entire
5508 string. Therefore, if it's desired to match a sequence anywhere within
5509 a string, the pattern must start and end with a percent sign.
5510 </para>
5512 <para>
5513 To match a literal underscore or percent sign without matching
5514 other characters, the respective character in
5515 <replaceable>pattern</replaceable> must be
5516 preceded by the escape character. The default escape
5517 character is the backslash but a different one can be selected by
5518 using the <literal>ESCAPE</literal> clause. To match the escape
5519 character itself, write two escape characters.
5520 </para>
5522 <note>
5523 <para>
5524 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
5525 any backslashes you write in literal string constants will need to be
5526 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
5527 </para>
5528 </note>
5530 <para>
5531 It's also possible to select no escape character by writing
5532 <literal>ESCAPE ''</literal>. This effectively disables the
5533 escape mechanism, which makes it impossible to turn off the
5534 special meaning of underscore and percent signs in the pattern.
5535 </para>
5537 <para>
5538 According to the SQL standard, omitting <literal>ESCAPE</literal>
5539 means there is no escape character (rather than defaulting to a
5540 backslash), and a zero-length <literal>ESCAPE</literal> value is
5541 disallowed. <productname>PostgreSQL</productname>'s behavior in
5542 this regard is therefore slightly nonstandard.
5543 </para>
5545 <para>
5546 The key word <token>ILIKE</token> can be used instead of
5547 <token>LIKE</token> to make the match case-insensitive according to the
5548 active locale. (But this does not support nondeterministic collations.)
5549 This is not in the <acronym>SQL</acronym> standard but is a
5550 <productname>PostgreSQL</productname> extension.
5551 </para>
5553 <para>
5554 The operator <literal>~~</literal> is equivalent to
5555 <function>LIKE</function>, and <literal>~~*</literal> corresponds to
5556 <function>ILIKE</function>. There are also
5557 <literal>!~~</literal> and <literal>!~~*</literal> operators that
5558 represent <function>NOT LIKE</function> and <function>NOT
5559 ILIKE</function>, respectively. All of these operators are
5560 <productname>PostgreSQL</productname>-specific. You may see these
5561 operator names in <command>EXPLAIN</command> output and similar
5562 places, since the parser actually translates <function>LIKE</function>
5563 et al. to these operators.
5564 </para>
5566 <para>
5567 The phrases <function>LIKE</function>, <function>ILIKE</function>,
5568 <function>NOT LIKE</function>, and <function>NOT ILIKE</function> are
5569 generally treated as operators
5570 in <productname>PostgreSQL</productname> syntax; for example they can
5571 be used in <replaceable>expression</replaceable>
5572 <replaceable>operator</replaceable> ANY
5573 (<replaceable>subquery</replaceable>) constructs, although
5574 an <literal>ESCAPE</literal> clause cannot be included there. In some
5575 obscure cases it may be necessary to use the underlying operator names
5576 instead.
5577 </para>
5579 <para>
5580 Also see the starts-with operator <literal>^@</literal> and the
5581 corresponding <function>starts_with()</function> function, which are
5582 useful in cases where simply matching the beginning of a string is
5583 needed.
5584 </para>
5585 </sect2>
5588 <sect2 id="functions-similarto-regexp">
5589 <title><function>SIMILAR TO</function> Regular Expressions</title>
5591 <indexterm>
5592 <primary>regular expression</primary>
5593 <!-- <seealso>pattern matching</seealso> breaks index build -->
5594 </indexterm>
5596 <indexterm>
5597 <primary>SIMILAR TO</primary>
5598 </indexterm>
5599 <indexterm>
5600 <primary>substring</primary>
5601 </indexterm>
5603 <synopsis>
5604 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5605 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5606 </synopsis>
5608 <para>
5609 The <function>SIMILAR TO</function> operator returns true or
5610 false depending on whether its pattern matches the given string.
5611 It is similar to <function>LIKE</function>, except that it
5612 interprets the pattern using the SQL standard's definition of a
5613 regular expression. SQL regular expressions are a curious cross
5614 between <function>LIKE</function> notation and common (POSIX) regular
5615 expression notation.
5616 </para>
5618 <para>
5619 Like <function>LIKE</function>, the <function>SIMILAR TO</function>
5620 operator succeeds only if its pattern matches the entire string;
5621 this is unlike common regular expression behavior where the pattern
5622 can match any part of the string.
5623 Also like
5624 <function>LIKE</function>, <function>SIMILAR TO</function> uses
5625 <literal>_</literal> and <literal>%</literal> as wildcard characters denoting
5626 any single character and any string, respectively (these are
5627 comparable to <literal>.</literal> and <literal>.*</literal> in POSIX regular
5628 expressions).
5629 </para>
5631 <para>
5632 In addition to these facilities borrowed from <function>LIKE</function>,
5633 <function>SIMILAR TO</function> supports these pattern-matching
5634 metacharacters borrowed from POSIX regular expressions:
5636 <itemizedlist>
5637 <listitem>
5638 <para>
5639 <literal>|</literal> denotes alternation (either of two alternatives).
5640 </para>
5641 </listitem>
5642 <listitem>
5643 <para>
5644 <literal>*</literal> denotes repetition of the previous item zero
5645 or more times.
5646 </para>
5647 </listitem>
5648 <listitem>
5649 <para>
5650 <literal>+</literal> denotes repetition of the previous item one
5651 or more times.
5652 </para>
5653 </listitem>
5654 <listitem>
5655 <para>
5656 <literal>?</literal> denotes repetition of the previous item zero
5657 or one time.
5658 </para>
5659 </listitem>
5660 <listitem>
5661 <para>
5662 <literal>{</literal><replaceable>m</replaceable><literal>}</literal> denotes repetition
5663 of the previous item exactly <replaceable>m</replaceable> times.
5664 </para>
5665 </listitem>
5666 <listitem>
5667 <para>
5668 <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> denotes repetition
5669 of the previous item <replaceable>m</replaceable> or more times.
5670 </para>
5671 </listitem>
5672 <listitem>
5673 <para>
5674 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
5675 denotes repetition of the previous item at least <replaceable>m</replaceable> and
5676 not more than <replaceable>n</replaceable> times.
5677 </para>
5678 </listitem>
5679 <listitem>
5680 <para>
5681 Parentheses <literal>()</literal> can be used to group items into
5682 a single logical item.
5683 </para>
5684 </listitem>
5685 <listitem>
5686 <para>
5687 A bracket expression <literal>[...]</literal> specifies a character
5688 class, just as in POSIX regular expressions.
5689 </para>
5690 </listitem>
5691 </itemizedlist>
5693 Notice that the period (<literal>.</literal>) is not a metacharacter
5694 for <function>SIMILAR TO</function>.
5695 </para>
5697 <para>
5698 As with <function>LIKE</function>, a backslash disables the special
5699 meaning of any of these metacharacters. A different escape character
5700 can be specified with <literal>ESCAPE</literal>, or the escape
5701 capability can be disabled by writing <literal>ESCAPE ''</literal>.
5702 </para>
5704 <para>
5705 According to the SQL standard, omitting <literal>ESCAPE</literal>
5706 means there is no escape character (rather than defaulting to a
5707 backslash), and a zero-length <literal>ESCAPE</literal> value is
5708 disallowed. <productname>PostgreSQL</productname>'s behavior in
5709 this regard is therefore slightly nonstandard.
5710 </para>
5712 <para>
5713 Another nonstandard extension is that following the escape character
5714 with a letter or digit provides access to the escape sequences
5715 defined for POSIX regular expressions; see
5716 <xref linkend="posix-character-entry-escapes-table"/>,
5717 <xref linkend="posix-class-shorthand-escapes-table"/>, and
5718 <xref linkend="posix-constraint-escapes-table"/> below.
5719 </para>
5721 <para>
5722 Some examples:
5723 <programlisting>
5724 'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation>
5725 'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation>
5726 'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation>
5727 'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation>
5728 '-abc-' SIMILAR TO '%\mabc\M%' <lineannotation>true</lineannotation>
5729 'xabcy' SIMILAR TO '%\mabc\M%' <lineannotation>false</lineannotation>
5730 </programlisting>
5731 </para>
5733 <para>
5734 The <function>substring</function> function with three parameters
5735 provides extraction of a substring that matches an SQL
5736 regular expression pattern. The function can be written according
5737 to standard SQL syntax:
5738 <synopsis>
5739 substring(<replaceable>string</replaceable> similar <replaceable>pattern</replaceable> escape <replaceable>escape-character</replaceable>)
5740 </synopsis>
5741 or using the now obsolete SQL:1999 syntax:
5742 <synopsis>
5743 substring(<replaceable>string</replaceable> from <replaceable>pattern</replaceable> for <replaceable>escape-character</replaceable>)
5744 </synopsis>
5745 or as a plain three-argument function:
5746 <synopsis>
5747 substring(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>escape-character</replaceable>)
5748 </synopsis>
5749 As with <literal>SIMILAR TO</literal>, the
5750 specified pattern must match the entire data string, or else the
5751 function fails and returns null. To indicate the part of the
5752 pattern for which the matching data sub-string is of interest,
5753 the pattern should contain
5754 two occurrences of the escape character followed by a double quote
5755 (<literal>"</literal>). <!-- " font-lock sanity -->
5756 The text matching the portion of the pattern
5757 between these separators is returned when the match is successful.
5758 </para>
5760 <para>
5761 The escape-double-quote separators actually
5762 divide <function>substring</function>'s pattern into three independent
5763 regular expressions; for example, a vertical bar (<literal>|</literal>)
5764 in any of the three sections affects only that section. Also, the first
5765 and third of these regular expressions are defined to match the smallest
5766 possible amount of text, not the largest, when there is any ambiguity
5767 about how much of the data string matches which pattern. (In POSIX
5768 parlance, the first and third regular expressions are forced to be
5769 non-greedy.)
5770 </para>
5772 <para>
5773 As an extension to the SQL standard, <productname>PostgreSQL</productname>
5774 allows there to be just one escape-double-quote separator, in which case
5775 the third regular expression is taken as empty; or no separators, in which
5776 case the first and third regular expressions are taken as empty.
5777 </para>
5779 <para>
5780 Some examples, with <literal>#&quot;</literal> delimiting the return string:
5781 <programlisting>
5782 substring('foobar' similar '%#"o_b#"%' escape '#') <lineannotation>oob</lineannotation>
5783 substring('foobar' similar '#"o_b#"%' escape '#') <lineannotation>NULL</lineannotation>
5784 </programlisting>
5785 </para>
5786 </sect2>
5788 <sect2 id="functions-posix-regexp">
5789 <title><acronym>POSIX</acronym> Regular Expressions</title>
5791 <indexterm zone="functions-posix-regexp">
5792 <primary>regular expression</primary>
5793 <seealso>pattern matching</seealso>
5794 </indexterm>
5795 <indexterm>
5796 <primary>substring</primary>
5797 </indexterm>
5798 <indexterm>
5799 <primary>regexp_count</primary>
5800 </indexterm>
5801 <indexterm>
5802 <primary>regexp_instr</primary>
5803 </indexterm>
5804 <indexterm>
5805 <primary>regexp_like</primary>
5806 </indexterm>
5807 <indexterm>
5808 <primary>regexp_match</primary>
5809 </indexterm>
5810 <indexterm>
5811 <primary>regexp_matches</primary>
5812 </indexterm>
5813 <indexterm>
5814 <primary>regexp_replace</primary>
5815 </indexterm>
5816 <indexterm>
5817 <primary>regexp_split_to_table</primary>
5818 </indexterm>
5819 <indexterm>
5820 <primary>regexp_split_to_array</primary>
5821 </indexterm>
5822 <indexterm>
5823 <primary>regexp_substr</primary>
5824 </indexterm>
5826 <para>
5827 <xref linkend="functions-posix-table"/> lists the available
5828 operators for pattern matching using POSIX regular expressions.
5829 </para>
5831 <table id="functions-posix-table">
5832 <title>Regular Expression Match Operators</title>
5834 <tgroup cols="1">
5835 <thead>
5836 <row>
5837 <entry role="func_table_entry"><para role="func_signature">
5838 Operator
5839 </para>
5840 <para>
5841 Description
5842 </para>
5843 <para>
5844 Example(s)
5845 </para></entry>
5846 </row>
5847 </thead>
5849 <tbody>
5850 <row>
5851 <entry role="func_table_entry"><para role="func_signature">
5852 <type>text</type> <literal>~</literal> <type>text</type>
5853 <returnvalue>boolean</returnvalue>
5854 </para>
5855 <para>
5856 String matches regular expression, case sensitively
5857 </para>
5858 <para>
5859 <literal>'thomas' ~ 't.*ma'</literal>
5860 <returnvalue>t</returnvalue>
5861 </para></entry>
5862 </row>
5864 <row>
5865 <entry role="func_table_entry"><para role="func_signature">
5866 <type>text</type> <literal>~*</literal> <type>text</type>
5867 <returnvalue>boolean</returnvalue>
5868 </para>
5869 <para>
5870 String matches regular expression, case-insensitively
5871 </para>
5872 <para>
5873 <literal>'thomas' ~* 'T.*ma'</literal>
5874 <returnvalue>t</returnvalue>
5875 </para></entry>
5876 </row>
5878 <row>
5879 <entry role="func_table_entry"><para role="func_signature">
5880 <type>text</type> <literal>!~</literal> <type>text</type>
5881 <returnvalue>boolean</returnvalue>
5882 </para>
5883 <para>
5884 String does not match regular expression, case sensitively
5885 </para>
5886 <para>
5887 <literal>'thomas' !~ 't.*max'</literal>
5888 <returnvalue>t</returnvalue>
5889 </para></entry>
5890 </row>
5892 <row>
5893 <entry role="func_table_entry"><para role="func_signature">
5894 <type>text</type> <literal>!~*</literal> <type>text</type>
5895 <returnvalue>boolean</returnvalue>
5896 </para>
5897 <para>
5898 String does not match regular expression, case-insensitively
5899 </para>
5900 <para>
5901 <literal>'thomas' !~* 'T.*ma'</literal>
5902 <returnvalue>f</returnvalue>
5903 </para></entry>
5904 </row>
5905 </tbody>
5906 </tgroup>
5907 </table>
5909 <para>
5910 <acronym>POSIX</acronym> regular expressions provide a more
5911 powerful means for pattern matching than the <function>LIKE</function> and
5912 <function>SIMILAR TO</function> operators.
5913 Many Unix tools such as <command>egrep</command>,
5914 <command>sed</command>, or <command>awk</command> use a pattern
5915 matching language that is similar to the one described here.
5916 </para>
5918 <para>
5919 A regular expression is a character sequence that is an
5920 abbreviated definition of a set of strings (a <firstterm>regular
5921 set</firstterm>). A string is said to match a regular expression
5922 if it is a member of the regular set described by the regular
5923 expression. As with <function>LIKE</function>, pattern characters
5924 match string characters exactly unless they are special characters
5925 in the regular expression language &mdash; but regular expressions use
5926 different special characters than <function>LIKE</function> does.
5927 Unlike <function>LIKE</function> patterns, a
5928 regular expression is allowed to match anywhere within a string, unless
5929 the regular expression is explicitly anchored to the beginning or
5930 end of the string.
5931 </para>
5933 <para>
5934 Some examples:
5935 <programlisting>
5936 'abcd' ~ 'bc' <lineannotation>true</lineannotation>
5937 'abcd' ~ 'a.c' <lineannotation>true &mdash; dot matches any character</lineannotation>
5938 'abcd' ~ 'a.*d' <lineannotation>true &mdash; <literal>*</literal> repeats the preceding pattern item</lineannotation>
5939 'abcd' ~ '(b|x)' <lineannotation>true &mdash; <literal>|</literal> means OR, parentheses group</lineannotation>
5940 'abcd' ~ '^a' <lineannotation>true &mdash; <literal>^</literal> anchors to start of string</lineannotation>
5941 'abcd' ~ '^(b|c)' <lineannotation>false &mdash; would match except for anchoring</lineannotation>
5942 </programlisting>
5943 </para>
5945 <para>
5946 The <acronym>POSIX</acronym> pattern language is described in much
5947 greater detail below.
5948 </para>
5950 <para>
5951 The <function>substring</function> function with two parameters,
5952 <function>substring(<replaceable>string</replaceable> from
5953 <replaceable>pattern</replaceable>)</function>, provides extraction of a
5954 substring
5955 that matches a POSIX regular expression pattern. It returns null if
5956 there is no match, otherwise the first portion of the text that matched the
5957 pattern. But if the pattern contains any parentheses, the portion
5958 of the text that matched the first parenthesized subexpression (the
5959 one whose left parenthesis comes first) is
5960 returned. You can put parentheses around the whole expression
5961 if you want to use parentheses within it without triggering this
5962 exception. If you need parentheses in the pattern before the
5963 subexpression you want to extract, see the non-capturing parentheses
5964 described below.
5965 </para>
5967 <para>
5968 Some examples:
5969 <programlisting>
5970 substring('foobar' from 'o.b') <lineannotation>oob</lineannotation>
5971 substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation>
5972 </programlisting>
5973 </para>
5975 <para>
5976 The <function>regexp_count</function> function counts the number of
5977 places where a POSIX regular expression pattern matches a string.
5978 It has the syntax
5979 <function>regexp_count</function>(<replaceable>string</replaceable>,
5980 <replaceable>pattern</replaceable>
5981 <optional>, <replaceable>start</replaceable>
5982 <optional>, <replaceable>flags</replaceable>
5983 </optional></optional>).
5984 <replaceable>pattern</replaceable> is searched for
5985 in <replaceable>string</replaceable>, normally from the beginning of
5986 the string, but if the <replaceable>start</replaceable> parameter is
5987 provided then beginning from that character index.
5988 The <replaceable>flags</replaceable> parameter is an optional text
5989 string containing zero or more single-letter flags that change the
5990 function's behavior. For example, including <literal>i</literal> in
5991 <replaceable>flags</replaceable> specifies case-insensitive matching.
5992 Supported flags are described in
5993 <xref linkend="posix-embedded-options-table"/>.
5994 </para>
5996 <para>
5997 Some examples:
5998 <programlisting>
5999 regexp_count('ABCABCAXYaxy', 'A.') <lineannotation>3</lineannotation>
6000 regexp_count('ABCABCAXYaxy', 'A.', 1, 'i') <lineannotation>4</lineannotation>
6001 </programlisting>
6002 </para>
6004 <para>
6005 The <function>regexp_instr</function> function returns the starting or
6006 ending position of the <replaceable>N</replaceable>'th match of a
6007 POSIX regular expression pattern to a string, or zero if there is no
6008 such match. It has the syntax
6009 <function>regexp_instr</function>(<replaceable>string</replaceable>,
6010 <replaceable>pattern</replaceable>
6011 <optional>, <replaceable>start</replaceable>
6012 <optional>, <replaceable>N</replaceable>
6013 <optional>, <replaceable>endoption</replaceable>
6014 <optional>, <replaceable>flags</replaceable>
6015 <optional>, <replaceable>subexpr</replaceable>
6016 </optional></optional></optional></optional></optional>).
6017 <replaceable>pattern</replaceable> is searched for
6018 in <replaceable>string</replaceable>, normally from the beginning of
6019 the string, but if the <replaceable>start</replaceable> parameter is
6020 provided then beginning from that character index.
6021 If <replaceable>N</replaceable> is specified
6022 then the <replaceable>N</replaceable>'th match of the pattern
6023 is located, otherwise the first match is located.
6024 If the <replaceable>endoption</replaceable> parameter is omitted or
6025 specified as zero, the function returns the position of the first
6026 character of the match. Otherwise, <replaceable>endoption</replaceable>
6027 must be one, and the function returns the position of the character
6028 following the match.
6029 The <replaceable>flags</replaceable> parameter is an optional text
6030 string containing zero or more single-letter flags that change the
6031 function's behavior. Supported flags are described
6032 in <xref linkend="posix-embedded-options-table"/>.
6033 For a pattern containing parenthesized
6034 subexpressions, <replaceable>subexpr</replaceable> is an integer
6035 indicating which subexpression is of interest: the result identifies
6036 the position of the substring matching that subexpression.
6037 Subexpressions are numbered in the order of their leading parentheses.
6038 When <replaceable>subexpr</replaceable> is omitted or zero, the result
6039 identifies the position of the whole match regardless of
6040 parenthesized subexpressions.
6041 </para>
6043 <para>
6044 Some examples:
6045 <programlisting>
6046 regexp_instr('number of your street, town zip, FR', '[^,]+', 1, 2)
6047 <lineannotation>23</lineannotation>
6048 regexp_instr(string=>'ABCDEFGHI', pattern=>'(c..)(...)', start=>1, "N"=>1, endoption=>0, flags=>'i', subexpr=>2)
6049 <lineannotation>6</lineannotation>
6050 </programlisting>
6051 </para>
6053 <para>
6054 The <function>regexp_like</function> function checks whether a match
6055 of a POSIX regular expression pattern occurs within a string,
6056 returning boolean true or false. It has the syntax
6057 <function>regexp_like</function>(<replaceable>string</replaceable>,
6058 <replaceable>pattern</replaceable>
6059 <optional>, <replaceable>flags</replaceable> </optional>).
6060 The <replaceable>flags</replaceable> parameter is an optional text
6061 string containing zero or more single-letter flags that change the
6062 function's behavior. Supported flags are described
6063 in <xref linkend="posix-embedded-options-table"/>.
6064 This function has the same results as the <literal>~</literal>
6065 operator if no flags are specified. If only the <literal>i</literal>
6066 flag is specified, it has the same results as
6067 the <literal>~*</literal> operator.
6068 </para>
6070 <para>
6071 Some examples:
6072 <programlisting>
6073 regexp_like('Hello World', 'world') <lineannotation>false</lineannotation>
6074 regexp_like('Hello World', 'world', 'i') <lineannotation>true</lineannotation>
6075 </programlisting>
6076 </para>
6078 <para>
6079 The <function>regexp_match</function> function returns a text array of
6080 matching substring(s) within the first match of a POSIX
6081 regular expression pattern to a string. It has the syntax
6082 <function>regexp_match</function>(<replaceable>string</replaceable>,
6083 <replaceable>pattern</replaceable> <optional>, <replaceable>flags</replaceable> </optional>).
6084 If there is no match, the result is <literal>NULL</literal>.
6085 If a match is found, and the <replaceable>pattern</replaceable> contains no
6086 parenthesized subexpressions, then the result is a single-element text
6087 array containing the substring matching the whole pattern.
6088 If a match is found, and the <replaceable>pattern</replaceable> contains
6089 parenthesized subexpressions, then the result is a text array
6090 whose <replaceable>n</replaceable>'th element is the substring matching
6091 the <replaceable>n</replaceable>'th parenthesized subexpression of
6092 the <replaceable>pattern</replaceable> (not counting <quote>non-capturing</quote>
6093 parentheses; see below for details).
6094 The <replaceable>flags</replaceable> parameter is an optional text string
6095 containing zero or more single-letter flags that change the function's
6096 behavior. Supported flags are described
6097 in <xref linkend="posix-embedded-options-table"/>.
6098 </para>
6100 <para>
6101 Some examples:
6102 <programlisting>
6103 SELECT regexp_match('foobarbequebaz', 'bar.*que');
6104 regexp_match
6105 --------------
6106 {barbeque}
6107 (1 row)
6109 SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
6110 regexp_match
6111 --------------
6112 {bar,beque}
6113 (1 row)
6114 </programlisting>
6115 </para>
6117 <tip>
6118 <para>
6119 In the common case where you just want the whole matching substring
6120 or <literal>NULL</literal> for no match, the best solution is to
6121 use <function>regexp_substr()</function>.
6122 However, <function>regexp_substr()</function> only exists
6123 in <productname>PostgreSQL</productname> version 15 and up. When
6124 working in older versions, you can extract the first element
6125 of <function>regexp_match()</function>'s result, for example:
6126 <programlisting>
6127 SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[1];
6128 regexp_match
6129 --------------
6130 barbeque
6131 (1 row)
6132 </programlisting>
6133 </para>
6134 </tip>
6136 <para>
6137 The <function>regexp_matches</function> function returns a set of text arrays
6138 of matching substring(s) within matches of a POSIX regular
6139 expression pattern to a string. It has the same syntax as
6140 <function>regexp_match</function>.
6141 This function returns no rows if there is no match, one row if there is
6142 a match and the <literal>g</literal> flag is not given, or <replaceable>N</replaceable>
6143 rows if there are <replaceable>N</replaceable> matches and the <literal>g</literal> flag
6144 is given. Each returned row is a text array containing the whole
6145 matched substring or the substrings matching parenthesized
6146 subexpressions of the <replaceable>pattern</replaceable>, just as described above
6147 for <function>regexp_match</function>.
6148 <function>regexp_matches</function> accepts all the flags shown
6149 in <xref linkend="posix-embedded-options-table"/>, plus
6150 the <literal>g</literal> flag which commands it to return all matches, not
6151 just the first one.
6152 </para>
6154 <para>
6155 Some examples:
6156 <programlisting>
6157 SELECT regexp_matches('foo', 'not there');
6158 regexp_matches
6159 ----------------
6160 (0 rows)
6162 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
6163 regexp_matches
6164 ----------------
6165 {bar,beque}
6166 {bazil,barf}
6167 (2 rows)
6168 </programlisting>
6169 </para>
6171 <tip>
6172 <para>
6173 In most cases <function>regexp_matches()</function> should be used with
6174 the <literal>g</literal> flag, since if you only want the first match, it's
6175 easier and more efficient to use <function>regexp_match()</function>.
6176 However, <function>regexp_match()</function> only exists
6177 in <productname>PostgreSQL</productname> version 10 and up. When working in older
6178 versions, a common trick is to place a <function>regexp_matches()</function>
6179 call in a sub-select, for example:
6180 <programlisting>
6181 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
6182 </programlisting>
6183 This produces a text array if there's a match, or <literal>NULL</literal> if
6184 not, the same as <function>regexp_match()</function> would do. Without the
6185 sub-select, this query would produce no output at all for table rows
6186 without a match, which is typically not the desired behavior.
6187 </para>
6188 </tip>
6190 <para>
6191 The <function>regexp_replace</function> function provides substitution of
6192 new text for substrings that match POSIX regular expression patterns.
6193 It has the syntax
6194 <function>regexp_replace</function>(<replaceable>string</replaceable>,
6195 <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>
6196 <optional>, <replaceable>flags</replaceable> </optional>)
6198 <function>regexp_replace</function>(<replaceable>string</replaceable>,
6199 <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>,
6200 <replaceable>start</replaceable>
6201 <optional>, <replaceable>N</replaceable>
6202 <optional>, <replaceable>flags</replaceable> </optional></optional>).
6203 The source <replaceable>string</replaceable> is returned unchanged if
6204 there is no match to the <replaceable>pattern</replaceable>. If there is a
6205 match, the <replaceable>string</replaceable> is returned with the
6206 <replaceable>replacement</replaceable> string substituted for the matching
6207 substring. The <replaceable>replacement</replaceable> string can contain
6208 <literal>\</literal><replaceable>n</replaceable>, where <replaceable>n</replaceable> is 1
6209 through 9, to indicate that the source substring matching the
6210 <replaceable>n</replaceable>'th parenthesized subexpression of the pattern should be
6211 inserted, and it can contain <literal>\&amp;</literal> to indicate that the
6212 substring matching the entire pattern should be inserted. Write
6213 <literal>\\</literal> if you need to put a literal backslash in the replacement
6214 text.
6215 <replaceable>pattern</replaceable> is searched for
6216 in <replaceable>string</replaceable>, normally from the beginning of
6217 the string, but if the <replaceable>start</replaceable> parameter is
6218 provided then beginning from that character index.
6219 By default, only the first match of the pattern is replaced.
6220 If <replaceable>N</replaceable> is specified and is greater than zero,
6221 then the <replaceable>N</replaceable>'th match of the pattern
6222 is replaced.
6223 If the <literal>g</literal> flag is given, or
6224 if <replaceable>N</replaceable> is specified and is zero, then all
6225 matches at or after the <replaceable>start</replaceable> position are
6226 replaced. (The <literal>g</literal> flag is ignored
6227 when <replaceable>N</replaceable> is specified.)
6228 The <replaceable>flags</replaceable> parameter is an optional text
6229 string containing zero or more single-letter flags that change the
6230 function's behavior. Supported flags (though
6231 not <literal>g</literal>) are
6232 described in <xref linkend="posix-embedded-options-table"/>.
6233 </para>
6235 <para>
6236 Some examples:
6237 <programlisting>
6238 regexp_replace('foobarbaz', 'b..', 'X')
6239 <lineannotation>fooXbaz</lineannotation>
6240 regexp_replace('foobarbaz', 'b..', 'X', 'g')
6241 <lineannotation>fooXX</lineannotation>
6242 regexp_replace('foobarbaz', 'b(..)', 'X\1Y', 'g')
6243 <lineannotation>fooXarYXazY</lineannotation>
6244 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 0, 'i')
6245 <lineannotation>X PXstgrXSQL fXnctXXn</lineannotation>
6246 regexp_replace(string=>'A PostgreSQL function', pattern=>'a|e|i|o|u', replacement=>'X', start=>1, "N"=>3, flags=>'i')
6247 <lineannotation>A PostgrXSQL function</lineannotation>
6248 </programlisting>
6249 </para>
6251 <para>
6252 The <function>regexp_split_to_table</function> function splits a string using a POSIX
6253 regular expression pattern as a delimiter. It has the syntax
6254 <function>regexp_split_to_table</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
6255 <optional>, <replaceable>flags</replaceable> </optional>).
6256 If there is no match to the <replaceable>pattern</replaceable>, the function returns the
6257 <replaceable>string</replaceable>. If there is at least one match, for each match it returns
6258 the text from the end of the last match (or the beginning of the string)
6259 to the beginning of the match. When there are no more matches, it
6260 returns the text from the end of the last match to the end of the string.
6261 The <replaceable>flags</replaceable> parameter is an optional text string containing
6262 zero or more single-letter flags that change the function's behavior.
6263 <function>regexp_split_to_table</function> supports the flags described in
6264 <xref linkend="posix-embedded-options-table"/>.
6265 </para>
6267 <para>
6268 The <function>regexp_split_to_array</function> function behaves the same as
6269 <function>regexp_split_to_table</function>, except that <function>regexp_split_to_array</function>
6270 returns its result as an array of <type>text</type>. It has the syntax
6271 <function>regexp_split_to_array</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
6272 <optional>, <replaceable>flags</replaceable> </optional>).
6273 The parameters are the same as for <function>regexp_split_to_table</function>.
6274 </para>
6276 <para>
6277 Some examples:
6278 <programlisting>
6279 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo;
6281 -------
6283 quick
6284 brown
6286 jumps
6287 over
6289 lazy
6291 (9 rows)
6293 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+');
6294 regexp_split_to_array
6295 -----------------------------------------------
6296 {the,quick,brown,fox,jumps,over,the,lazy,dog}
6297 (1 row)
6299 SELECT foo FROM regexp_split_to_table('the quick brown fox', '\s*') AS foo;
6301 -----
6318 (16 rows)
6319 </programlisting>
6320 </para>
6322 <para>
6323 As the last example demonstrates, the regexp split functions ignore
6324 zero-length matches that occur at the start or end of the string
6325 or immediately after a previous match. This is contrary to the strict
6326 definition of regexp matching that is implemented by
6327 the other regexp functions, but is usually the most convenient behavior
6328 in practice. Other software systems such as Perl use similar definitions.
6329 </para>
6331 <para>
6332 The <function>regexp_substr</function> function returns the substring
6333 that matches a POSIX regular expression pattern,
6334 or <literal>NULL</literal> if there is no match. It has the syntax
6335 <function>regexp_substr</function>(<replaceable>string</replaceable>,
6336 <replaceable>pattern</replaceable>
6337 <optional>, <replaceable>start</replaceable>
6338 <optional>, <replaceable>N</replaceable>
6339 <optional>, <replaceable>flags</replaceable>
6340 <optional>, <replaceable>subexpr</replaceable>
6341 </optional></optional></optional></optional>).
6342 <replaceable>pattern</replaceable> is searched for
6343 in <replaceable>string</replaceable>, normally from the beginning of
6344 the string, but if the <replaceable>start</replaceable> parameter is
6345 provided then beginning from that character index.
6346 If <replaceable>N</replaceable> is specified
6347 then the <replaceable>N</replaceable>'th match of the pattern
6348 is returned, otherwise the first match is returned.
6349 The <replaceable>flags</replaceable> parameter is an optional text
6350 string containing zero or more single-letter flags that change the
6351 function's behavior. Supported flags are described
6352 in <xref linkend="posix-embedded-options-table"/>.
6353 For a pattern containing parenthesized
6354 subexpressions, <replaceable>subexpr</replaceable> is an integer
6355 indicating which subexpression is of interest: the result is the
6356 substring matching that subexpression.
6357 Subexpressions are numbered in the order of their leading parentheses.
6358 When <replaceable>subexpr</replaceable> is omitted or zero, the result
6359 is the whole match regardless of parenthesized subexpressions.
6360 </para>
6362 <para>
6363 Some examples:
6364 <programlisting>
6365 regexp_substr('number of your street, town zip, FR', '[^,]+', 1, 2)
6366 <lineannotation> town zip</lineannotation>
6367 regexp_substr('ABCDEFGHI', '(c..)(...)', 1, 1, 'i', 2)
6368 <lineannotation>FGH</lineannotation>
6369 </programlisting>
6370 </para>
6372 <!-- derived from the re_syntax.n man page -->
6374 <sect3 id="posix-syntax-details">
6375 <title>Regular Expression Details</title>
6377 <para>
6378 <productname>PostgreSQL</productname>'s regular expressions are implemented
6379 using a software package written by Henry Spencer. Much of
6380 the description of regular expressions below is copied verbatim from his
6381 manual.
6382 </para>
6384 <para>
6385 Regular expressions (<acronym>RE</acronym>s), as defined in
6386 <acronym>POSIX</acronym> 1003.2, come in two forms:
6387 <firstterm>extended</firstterm> <acronym>RE</acronym>s or <acronym>ERE</acronym>s
6388 (roughly those of <command>egrep</command>), and
6389 <firstterm>basic</firstterm> <acronym>RE</acronym>s or <acronym>BRE</acronym>s
6390 (roughly those of <command>ed</command>).
6391 <productname>PostgreSQL</productname> supports both forms, and
6392 also implements some extensions
6393 that are not in the POSIX standard, but have become widely used
6394 due to their availability in programming languages such as Perl and Tcl.
6395 <acronym>RE</acronym>s using these non-POSIX extensions are called
6396 <firstterm>advanced</firstterm> <acronym>RE</acronym>s or <acronym>ARE</acronym>s
6397 in this documentation. AREs are almost an exact superset of EREs,
6398 but BREs have several notational incompatibilities (as well as being
6399 much more limited).
6400 We first describe the ARE and ERE forms, noting features that apply
6401 only to AREs, and then describe how BREs differ.
6402 </para>
6404 <note>
6405 <para>
6406 <productname>PostgreSQL</productname> always initially presumes that a regular
6407 expression follows the ARE rules. However, the more limited ERE or
6408 BRE rules can be chosen by prepending an <firstterm>embedded option</firstterm>
6409 to the RE pattern, as described in <xref linkend="posix-metasyntax"/>.
6410 This can be useful for compatibility with applications that expect
6411 exactly the <acronym>POSIX</acronym> 1003.2 rules.
6412 </para>
6413 </note>
6415 <para>
6416 A regular expression is defined as one or more
6417 <firstterm>branches</firstterm>, separated by
6418 <literal>|</literal>. It matches anything that matches one of the
6419 branches.
6420 </para>
6422 <para>
6423 A branch is zero or more <firstterm>quantified atoms</firstterm> or
6424 <firstterm>constraints</firstterm>, concatenated.
6425 It matches a match for the first, followed by a match for the second, etc.;
6426 an empty branch matches the empty string.
6427 </para>
6429 <para>
6430 A quantified atom is an <firstterm>atom</firstterm> possibly followed
6431 by a single <firstterm>quantifier</firstterm>.
6432 Without a quantifier, it matches a match for the atom.
6433 With a quantifier, it can match some number of matches of the atom.
6434 An <firstterm>atom</firstterm> can be any of the possibilities
6435 shown in <xref linkend="posix-atoms-table"/>.
6436 The possible quantifiers and their meanings are shown in
6437 <xref linkend="posix-quantifiers-table"/>.
6438 </para>
6440 <para>
6441 A <firstterm>constraint</firstterm> matches an empty string, but matches only when
6442 specific conditions are met. A constraint can be used where an atom
6443 could be used, except it cannot be followed by a quantifier.
6444 The simple constraints are shown in
6445 <xref linkend="posix-constraints-table"/>;
6446 some more constraints are described later.
6447 </para>
6450 <table id="posix-atoms-table">
6451 <title>Regular Expression Atoms</title>
6453 <tgroup cols="2">
6454 <thead>
6455 <row>
6456 <entry>Atom</entry>
6457 <entry>Description</entry>
6458 </row>
6459 </thead>
6461 <tbody>
6462 <row>
6463 <entry> <literal>(</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6464 <entry> (where <replaceable>re</replaceable> is any regular expression)
6465 matches a match for
6466 <replaceable>re</replaceable>, with the match noted for possible reporting </entry>
6467 </row>
6469 <row>
6470 <entry> <literal>(?:</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6471 <entry> as above, but the match is not noted for reporting
6472 (a <quote>non-capturing</quote> set of parentheses)
6473 (AREs only) </entry>
6474 </row>
6476 <row>
6477 <entry> <literal>.</literal> </entry>
6478 <entry> matches any single character </entry>
6479 </row>
6481 <row>
6482 <entry> <literal>[</literal><replaceable>chars</replaceable><literal>]</literal> </entry>
6483 <entry> a <firstterm>bracket expression</firstterm>,
6484 matching any one of the <replaceable>chars</replaceable> (see
6485 <xref linkend="posix-bracket-expressions"/> for more detail) </entry>
6486 </row>
6488 <row>
6489 <entry> <literal>\</literal><replaceable>k</replaceable> </entry>
6490 <entry> (where <replaceable>k</replaceable> is a non-alphanumeric character)
6491 matches that character taken as an ordinary character,
6492 e.g., <literal>\\</literal> matches a backslash character </entry>
6493 </row>
6495 <row>
6496 <entry> <literal>\</literal><replaceable>c</replaceable> </entry>
6497 <entry> where <replaceable>c</replaceable> is alphanumeric
6498 (possibly followed by other characters)
6499 is an <firstterm>escape</firstterm>, see <xref linkend="posix-escape-sequences"/>
6500 (AREs only; in EREs and BREs, this matches <replaceable>c</replaceable>) </entry>
6501 </row>
6503 <row>
6504 <entry> <literal>{</literal> </entry>
6505 <entry> when followed by a character other than a digit,
6506 matches the left-brace character <literal>{</literal>;
6507 when followed by a digit, it is the beginning of a
6508 <replaceable>bound</replaceable> (see below) </entry>
6509 </row>
6511 <row>
6512 <entry> <replaceable>x</replaceable> </entry>
6513 <entry> where <replaceable>x</replaceable> is a single character with no other
6514 significance, matches that character </entry>
6515 </row>
6516 </tbody>
6517 </tgroup>
6518 </table>
6520 <para>
6521 An RE cannot end with a backslash (<literal>\</literal>).
6522 </para>
6524 <note>
6525 <para>
6526 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
6527 any backslashes you write in literal string constants will need to be
6528 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
6529 </para>
6530 </note>
6532 <table id="posix-quantifiers-table">
6533 <title>Regular Expression Quantifiers</title>
6535 <tgroup cols="2">
6536 <thead>
6537 <row>
6538 <entry>Quantifier</entry>
6539 <entry>Matches</entry>
6540 </row>
6541 </thead>
6543 <tbody>
6544 <row>
6545 <entry> <literal>*</literal> </entry>
6546 <entry> a sequence of 0 or more matches of the atom </entry>
6547 </row>
6549 <row>
6550 <entry> <literal>+</literal> </entry>
6551 <entry> a sequence of 1 or more matches of the atom </entry>
6552 </row>
6554 <row>
6555 <entry> <literal>?</literal> </entry>
6556 <entry> a sequence of 0 or 1 matches of the atom </entry>
6557 </row>
6559 <row>
6560 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6561 <entry> a sequence of exactly <replaceable>m</replaceable> matches of the atom </entry>
6562 </row>
6564 <row>
6565 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6566 <entry> a sequence of <replaceable>m</replaceable> or more matches of the atom </entry>
6567 </row>
6569 <row>
6570 <entry>
6571 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6572 <entry> a sequence of <replaceable>m</replaceable> through <replaceable>n</replaceable>
6573 (inclusive) matches of the atom; <replaceable>m</replaceable> cannot exceed
6574 <replaceable>n</replaceable> </entry>
6575 </row>
6577 <row>
6578 <entry> <literal>*?</literal> </entry>
6579 <entry> non-greedy version of <literal>*</literal> </entry>
6580 </row>
6582 <row>
6583 <entry> <literal>+?</literal> </entry>
6584 <entry> non-greedy version of <literal>+</literal> </entry>
6585 </row>
6587 <row>
6588 <entry> <literal>??</literal> </entry>
6589 <entry> non-greedy version of <literal>?</literal> </entry>
6590 </row>
6592 <row>
6593 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}?</literal> </entry>
6594 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6595 </row>
6597 <row>
6598 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}?</literal> </entry>
6599 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6600 </row>
6602 <row>
6603 <entry>
6604 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal> </entry>
6605 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6606 </row>
6607 </tbody>
6608 </tgroup>
6609 </table>
6611 <para>
6612 The forms using <literal>{</literal><replaceable>...</replaceable><literal>}</literal>
6613 are known as <firstterm>bounds</firstterm>.
6614 The numbers <replaceable>m</replaceable> and <replaceable>n</replaceable> within a bound are
6615 unsigned decimal integers with permissible values from 0 to 255 inclusive.
6616 </para>
6618 <para>
6619 <firstterm>Non-greedy</firstterm> quantifiers (available in AREs only) match the
6620 same possibilities as their corresponding normal (<firstterm>greedy</firstterm>)
6621 counterparts, but prefer the smallest number rather than the largest
6622 number of matches.
6623 See <xref linkend="posix-matching-rules"/> for more detail.
6624 </para>
6626 <note>
6627 <para>
6628 A quantifier cannot immediately follow another quantifier, e.g.,
6629 <literal>**</literal> is invalid.
6630 A quantifier cannot
6631 begin an expression or subexpression or follow
6632 <literal>^</literal> or <literal>|</literal>.
6633 </para>
6634 </note>
6636 <table id="posix-constraints-table">
6637 <title>Regular Expression Constraints</title>
6639 <tgroup cols="2">
6640 <thead>
6641 <row>
6642 <entry>Constraint</entry>
6643 <entry>Description</entry>
6644 </row>
6645 </thead>
6647 <tbody>
6648 <row>
6649 <entry> <literal>^</literal> </entry>
6650 <entry> matches at the beginning of the string </entry>
6651 </row>
6653 <row>
6654 <entry> <literal>$</literal> </entry>
6655 <entry> matches at the end of the string </entry>
6656 </row>
6658 <row>
6659 <entry> <literal>(?=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6660 <entry> <firstterm>positive lookahead</firstterm> matches at any point
6661 where a substring matching <replaceable>re</replaceable> begins
6662 (AREs only) </entry>
6663 </row>
6665 <row>
6666 <entry> <literal>(?!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6667 <entry> <firstterm>negative lookahead</firstterm> matches at any point
6668 where no substring matching <replaceable>re</replaceable> begins
6669 (AREs only) </entry>
6670 </row>
6672 <row>
6673 <entry> <literal>(?&lt;=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6674 <entry> <firstterm>positive lookbehind</firstterm> matches at any point
6675 where a substring matching <replaceable>re</replaceable> ends
6676 (AREs only) </entry>
6677 </row>
6679 <row>
6680 <entry> <literal>(?&lt;!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6681 <entry> <firstterm>negative lookbehind</firstterm> matches at any point
6682 where no substring matching <replaceable>re</replaceable> ends
6683 (AREs only) </entry>
6684 </row>
6685 </tbody>
6686 </tgroup>
6687 </table>
6689 <para>
6690 Lookahead and lookbehind constraints cannot contain <firstterm>back
6691 references</firstterm> (see <xref linkend="posix-escape-sequences"/>),
6692 and all parentheses within them are considered non-capturing.
6693 </para>
6694 </sect3>
6696 <sect3 id="posix-bracket-expressions">
6697 <title>Bracket Expressions</title>
6699 <para>
6700 A <firstterm>bracket expression</firstterm> is a list of
6701 characters enclosed in <literal>[]</literal>. It normally matches
6702 any single character from the list (but see below). If the list
6703 begins with <literal>^</literal>, it matches any single character
6704 <emphasis>not</emphasis> from the rest of the list.
6705 If two characters
6706 in the list are separated by <literal>-</literal>, this is
6707 shorthand for the full range of characters between those two
6708 (inclusive) in the collating sequence,
6709 e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
6710 any decimal digit. It is illegal for two ranges to share an
6711 endpoint, e.g., <literal>a-c-e</literal>. Ranges are very
6712 collating-sequence-dependent, so portable programs should avoid
6713 relying on them.
6714 </para>
6716 <para>
6717 To include a literal <literal>]</literal> in the list, make it the
6718 first character (after <literal>^</literal>, if that is used). To
6719 include a literal <literal>-</literal>, make it the first or last
6720 character, or the second endpoint of a range. To use a literal
6721 <literal>-</literal> as the first endpoint of a range, enclose it
6722 in <literal>[.</literal> and <literal>.]</literal> to make it a
6723 collating element (see below). With the exception of these characters,
6724 some combinations using <literal>[</literal>
6725 (see next paragraphs), and escapes (AREs only), all other special
6726 characters lose their special significance within a bracket expression.
6727 In particular, <literal>\</literal> is not special when following
6728 ERE or BRE rules, though it is special (as introducing an escape)
6729 in AREs.
6730 </para>
6732 <para>
6733 Within a bracket expression, a collating element (a character, a
6734 multiple-character sequence that collates as if it were a single
6735 character, or a collating-sequence name for either) enclosed in
6736 <literal>[.</literal> and <literal>.]</literal> stands for the
6737 sequence of characters of that collating element. The sequence is
6738 treated as a single element of the bracket expression's list. This
6739 allows a bracket
6740 expression containing a multiple-character collating element to
6741 match more than one character, e.g., if the collating sequence
6742 includes a <literal>ch</literal> collating element, then the RE
6743 <literal>[[.ch.]]*c</literal> matches the first five characters of
6744 <literal>chchcc</literal>.
6745 </para>
6747 <note>
6748 <para>
6749 <productname>PostgreSQL</productname> currently does not support multi-character collating
6750 elements. This information describes possible future behavior.
6751 </para>
6752 </note>
6754 <para>
6755 Within a bracket expression, a collating element enclosed in
6756 <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
6757 class</firstterm>, standing for the sequences of characters of all collating
6758 elements equivalent to that one, including itself. (If there are
6759 no other equivalent collating elements, the treatment is as if the
6760 enclosing delimiters were <literal>[.</literal> and
6761 <literal>.]</literal>.) For example, if <literal>o</literal> and
6762 <literal>^</literal> are the members of an equivalence class, then
6763 <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
6764 <literal>[o^]</literal> are all synonymous. An equivalence class
6765 cannot be an endpoint of a range.
6766 </para>
6768 <para>
6769 Within a bracket expression, the name of a character class
6770 enclosed in <literal>[:</literal> and <literal>:]</literal> stands
6771 for the list of all characters belonging to that class. A character
6772 class cannot be used as an endpoint of a range.
6773 The <acronym>POSIX</acronym> standard defines these character class
6774 names:
6775 <literal>alnum</literal> (letters and numeric digits),
6776 <literal>alpha</literal> (letters),
6777 <literal>blank</literal> (space and tab),
6778 <literal>cntrl</literal> (control characters),
6779 <literal>digit</literal> (numeric digits),
6780 <literal>graph</literal> (printable characters except space),
6781 <literal>lower</literal> (lower-case letters),
6782 <literal>print</literal> (printable characters including space),
6783 <literal>punct</literal> (punctuation),
6784 <literal>space</literal> (any white space),
6785 <literal>upper</literal> (upper-case letters),
6786 and <literal>xdigit</literal> (hexadecimal digits).
6787 The behavior of these standard character classes is generally
6788 consistent across platforms for characters in the 7-bit ASCII set.
6789 Whether a given non-ASCII character is considered to belong to one
6790 of these classes depends on the <firstterm>collation</firstterm>
6791 that is used for the regular-expression function or operator
6792 (see <xref linkend="collation"/>), or by default on the
6793 database's <envar>LC_CTYPE</envar> locale setting (see
6794 <xref linkend="locale"/>). The classification of non-ASCII
6795 characters can vary across platforms even in similarly-named
6796 locales. (But the <literal>C</literal> locale never considers any
6797 non-ASCII characters to belong to any of these classes.)
6798 In addition to these standard character
6799 classes, <productname>PostgreSQL</productname> defines
6800 the <literal>word</literal> character class, which is the same as
6801 <literal>alnum</literal> plus the underscore (<literal>_</literal>)
6802 character, and
6803 the <literal>ascii</literal> character class, which contains exactly
6804 the 7-bit ASCII set.
6805 </para>
6807 <para>
6808 There are two special cases of bracket expressions: the bracket
6809 expressions <literal>[[:&lt;:]]</literal> and
6810 <literal>[[:&gt;:]]</literal> are constraints,
6811 matching empty strings at the beginning
6812 and end of a word respectively. A word is defined as a sequence
6813 of word characters that is neither preceded nor followed by word
6814 characters. A word character is any character belonging to the
6815 <literal>word</literal> character class, that is, any letter, digit,
6816 or underscore. This is an extension, compatible with but not
6817 specified by <acronym>POSIX</acronym> 1003.2, and should be used with
6818 caution in software intended to be portable to other systems.
6819 The constraint escapes described below are usually preferable; they
6820 are no more standard, but are easier to type.
6821 </para>
6822 </sect3>
6824 <sect3 id="posix-escape-sequences">
6825 <title>Regular Expression Escapes</title>
6827 <para>
6828 <firstterm>Escapes</firstterm> are special sequences beginning with <literal>\</literal>
6829 followed by an alphanumeric character. Escapes come in several varieties:
6830 character entry, class shorthands, constraint escapes, and back references.
6831 A <literal>\</literal> followed by an alphanumeric character but not constituting
6832 a valid escape is illegal in AREs.
6833 In EREs, there are no escapes: outside a bracket expression,
6834 a <literal>\</literal> followed by an alphanumeric character merely stands for
6835 that character as an ordinary character, and inside a bracket expression,
6836 <literal>\</literal> is an ordinary character.
6837 (The latter is the one actual incompatibility between EREs and AREs.)
6838 </para>
6840 <para>
6841 <firstterm>Character-entry escapes</firstterm> exist to make it easier to specify
6842 non-printing and other inconvenient characters in REs. They are
6843 shown in <xref linkend="posix-character-entry-escapes-table"/>.
6844 </para>
6846 <para>
6847 <firstterm>Class-shorthand escapes</firstterm> provide shorthands for certain
6848 commonly-used character classes. They are
6849 shown in <xref linkend="posix-class-shorthand-escapes-table"/>.
6850 </para>
6852 <para>
6853 A <firstterm>constraint escape</firstterm> is a constraint,
6854 matching the empty string if specific conditions are met,
6855 written as an escape. They are
6856 shown in <xref linkend="posix-constraint-escapes-table"/>.
6857 </para>
6859 <para>
6860 A <firstterm>back reference</firstterm> (<literal>\</literal><replaceable>n</replaceable>) matches the
6861 same string matched by the previous parenthesized subexpression specified
6862 by the number <replaceable>n</replaceable>
6863 (see <xref linkend="posix-constraint-backref-table"/>). For example,
6864 <literal>([bc])\1</literal> matches <literal>bb</literal> or <literal>cc</literal>
6865 but not <literal>bc</literal> or <literal>cb</literal>.
6866 The subexpression must entirely precede the back reference in the RE.
6867 Subexpressions are numbered in the order of their leading parentheses.
6868 Non-capturing parentheses do not define subexpressions.
6869 The back reference considers only the string characters matched by the
6870 referenced subexpression, not any constraints contained in it. For
6871 example, <literal>(^\d)\1</literal> will match <literal>22</literal>.
6872 </para>
6874 <table id="posix-character-entry-escapes-table">
6875 <title>Regular Expression Character-Entry Escapes</title>
6877 <tgroup cols="2">
6878 <thead>
6879 <row>
6880 <entry>Escape</entry>
6881 <entry>Description</entry>
6882 </row>
6883 </thead>
6885 <tbody>
6886 <row>
6887 <entry> <literal>\a</literal> </entry>
6888 <entry> alert (bell) character, as in C </entry>
6889 </row>
6891 <row>
6892 <entry> <literal>\b</literal> </entry>
6893 <entry> backspace, as in C </entry>
6894 </row>
6896 <row>
6897 <entry> <literal>\B</literal> </entry>
6898 <entry> synonym for backslash (<literal>\</literal>) to help reduce the need for backslash
6899 doubling </entry>
6900 </row>
6902 <row>
6903 <entry> <literal>\c</literal><replaceable>X</replaceable> </entry>
6904 <entry> (where <replaceable>X</replaceable> is any character) the character whose
6905 low-order 5 bits are the same as those of
6906 <replaceable>X</replaceable>, and whose other bits are all zero </entry>
6907 </row>
6909 <row>
6910 <entry> <literal>\e</literal> </entry>
6911 <entry> the character whose collating-sequence name
6912 is <literal>ESC</literal>,
6913 or failing that, the character with octal value <literal>033</literal> </entry>
6914 </row>
6916 <row>
6917 <entry> <literal>\f</literal> </entry>
6918 <entry> form feed, as in C </entry>
6919 </row>
6921 <row>
6922 <entry> <literal>\n</literal> </entry>
6923 <entry> newline, as in C </entry>
6924 </row>
6926 <row>
6927 <entry> <literal>\r</literal> </entry>
6928 <entry> carriage return, as in C </entry>
6929 </row>
6931 <row>
6932 <entry> <literal>\t</literal> </entry>
6933 <entry> horizontal tab, as in C </entry>
6934 </row>
6936 <row>
6937 <entry> <literal>\u</literal><replaceable>wxyz</replaceable> </entry>
6938 <entry> (where <replaceable>wxyz</replaceable> is exactly four hexadecimal digits)
6939 the character whose hexadecimal value is
6940 <literal>0x</literal><replaceable>wxyz</replaceable>
6941 </entry>
6942 </row>
6944 <row>
6945 <entry> <literal>\U</literal><replaceable>stuvwxyz</replaceable> </entry>
6946 <entry> (where <replaceable>stuvwxyz</replaceable> is exactly eight hexadecimal
6947 digits)
6948 the character whose hexadecimal value is
6949 <literal>0x</literal><replaceable>stuvwxyz</replaceable>
6950 </entry>
6951 </row>
6953 <row>
6954 <entry> <literal>\v</literal> </entry>
6955 <entry> vertical tab, as in C </entry>
6956 </row>
6958 <row>
6959 <entry> <literal>\x</literal><replaceable>hhh</replaceable> </entry>
6960 <entry> (where <replaceable>hhh</replaceable> is any sequence of hexadecimal
6961 digits)
6962 the character whose hexadecimal value is
6963 <literal>0x</literal><replaceable>hhh</replaceable>
6964 (a single character no matter how many hexadecimal digits are used)
6965 </entry>
6966 </row>
6968 <row>
6969 <entry> <literal>\0</literal> </entry>
6970 <entry> the character whose value is <literal>0</literal> (the null byte)</entry>
6971 </row>
6973 <row>
6974 <entry> <literal>\</literal><replaceable>xy</replaceable> </entry>
6975 <entry> (where <replaceable>xy</replaceable> is exactly two octal digits,
6976 and is not a <firstterm>back reference</firstterm>)
6977 the character whose octal value is
6978 <literal>0</literal><replaceable>xy</replaceable> </entry>
6979 </row>
6981 <row>
6982 <entry> <literal>\</literal><replaceable>xyz</replaceable> </entry>
6983 <entry> (where <replaceable>xyz</replaceable> is exactly three octal digits,
6984 and is not a <firstterm>back reference</firstterm>)
6985 the character whose octal value is
6986 <literal>0</literal><replaceable>xyz</replaceable> </entry>
6987 </row>
6988 </tbody>
6989 </tgroup>
6990 </table>
6992 <para>
6993 Hexadecimal digits are <literal>0</literal>-<literal>9</literal>,
6994 <literal>a</literal>-<literal>f</literal>, and <literal>A</literal>-<literal>F</literal>.
6995 Octal digits are <literal>0</literal>-<literal>7</literal>.
6996 </para>
6998 <para>
6999 Numeric character-entry escapes specifying values outside the ASCII range
7000 (0&ndash;127) have meanings dependent on the database encoding. When the
7001 encoding is UTF-8, escape values are equivalent to Unicode code points,
7002 for example <literal>\u1234</literal> means the character <literal>U+1234</literal>.
7003 For other multibyte encodings, character-entry escapes usually just
7004 specify the concatenation of the byte values for the character. If the
7005 escape value does not correspond to any legal character in the database
7006 encoding, no error will be raised, but it will never match any data.
7007 </para>
7009 <para>
7010 The character-entry escapes are always taken as ordinary characters.
7011 For example, <literal>\135</literal> is <literal>]</literal> in ASCII, but
7012 <literal>\135</literal> does not terminate a bracket expression.
7013 </para>
7015 <table id="posix-class-shorthand-escapes-table">
7016 <title>Regular Expression Class-Shorthand Escapes</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>\d</literal> </entry>
7029 <entry> matches any digit, like
7030 <literal>[[:digit:]]</literal> </entry>
7031 </row>
7033 <row>
7034 <entry> <literal>\s</literal> </entry>
7035 <entry> matches any whitespace character, like
7036 <literal>[[:space:]]</literal> </entry>
7037 </row>
7039 <row>
7040 <entry> <literal>\w</literal> </entry>
7041 <entry> matches any word character, like
7042 <literal>[[:word:]]</literal> </entry>
7043 </row>
7045 <row>
7046 <entry> <literal>\D</literal> </entry>
7047 <entry> matches any non-digit, like
7048 <literal>[^[:digit:]]</literal> </entry>
7049 </row>
7051 <row>
7052 <entry> <literal>\S</literal> </entry>
7053 <entry> matches any non-whitespace character, like
7054 <literal>[^[:space:]]</literal> </entry>
7055 </row>
7057 <row>
7058 <entry> <literal>\W</literal> </entry>
7059 <entry> matches any non-word character, like
7060 <literal>[^[:word:]]</literal> </entry>
7061 </row>
7062 </tbody>
7063 </tgroup>
7064 </table>
7066 <para>
7067 The class-shorthand escapes also work within bracket expressions,
7068 although the definitions shown above are not quite syntactically
7069 valid in that context.
7070 For example, <literal>[a-c\d]</literal> is equivalent to
7071 <literal>[a-c[:digit:]]</literal>.
7072 </para>
7074 <table id="posix-constraint-escapes-table">
7075 <title>Regular Expression Constraint Escapes</title>
7077 <tgroup cols="2">
7078 <thead>
7079 <row>
7080 <entry>Escape</entry>
7081 <entry>Description</entry>
7082 </row>
7083 </thead>
7085 <tbody>
7086 <row>
7087 <entry> <literal>\A</literal> </entry>
7088 <entry> matches only at the beginning of the string
7089 (see <xref linkend="posix-matching-rules"/> for how this differs from
7090 <literal>^</literal>) </entry>
7091 </row>
7093 <row>
7094 <entry> <literal>\m</literal> </entry>
7095 <entry> matches only at the beginning of a word </entry>
7096 </row>
7098 <row>
7099 <entry> <literal>\M</literal> </entry>
7100 <entry> matches only at the end of a word </entry>
7101 </row>
7103 <row>
7104 <entry> <literal>\y</literal> </entry>
7105 <entry> matches only at the beginning or end of a word </entry>
7106 </row>
7108 <row>
7109 <entry> <literal>\Y</literal> </entry>
7110 <entry> matches only at a point that is not the beginning or end of a
7111 word </entry>
7112 </row>
7114 <row>
7115 <entry> <literal>\Z</literal> </entry>
7116 <entry> matches only at the end of the string
7117 (see <xref linkend="posix-matching-rules"/> for how this differs from
7118 <literal>$</literal>) </entry>
7119 </row>
7120 </tbody>
7121 </tgroup>
7122 </table>
7124 <para>
7125 A word is defined as in the specification of
7126 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal> above.
7127 Constraint escapes are illegal within bracket expressions.
7128 </para>
7130 <table id="posix-constraint-backref-table">
7131 <title>Regular Expression Back References</title>
7133 <tgroup cols="2">
7134 <thead>
7135 <row>
7136 <entry>Escape</entry>
7137 <entry>Description</entry>
7138 </row>
7139 </thead>
7141 <tbody>
7142 <row>
7143 <entry> <literal>\</literal><replaceable>m</replaceable> </entry>
7144 <entry> (where <replaceable>m</replaceable> is a nonzero digit)
7145 a back reference to the <replaceable>m</replaceable>'th subexpression </entry>
7146 </row>
7148 <row>
7149 <entry> <literal>\</literal><replaceable>mnn</replaceable> </entry>
7150 <entry> (where <replaceable>m</replaceable> is a nonzero digit, and
7151 <replaceable>nn</replaceable> is some more digits, and the decimal value
7152 <replaceable>mnn</replaceable> is not greater than the number of closing capturing
7153 parentheses seen so far)
7154 a back reference to the <replaceable>mnn</replaceable>'th subexpression </entry>
7155 </row>
7156 </tbody>
7157 </tgroup>
7158 </table>
7160 <note>
7161 <para>
7162 There is an inherent ambiguity between octal character-entry
7163 escapes and back references, which is resolved by the following heuristics,
7164 as hinted at above.
7165 A leading zero always indicates an octal escape.
7166 A single non-zero digit, not followed by another digit,
7167 is always taken as a back reference.
7168 A multi-digit sequence not starting with a zero is taken as a back
7169 reference if it comes after a suitable subexpression
7170 (i.e., the number is in the legal range for a back reference),
7171 and otherwise is taken as octal.
7172 </para>
7173 </note>
7174 </sect3>
7176 <sect3 id="posix-metasyntax">
7177 <title>Regular Expression Metasyntax</title>
7179 <para>
7180 In addition to the main syntax described above, there are some special
7181 forms and miscellaneous syntactic facilities available.
7182 </para>
7184 <para>
7185 An RE can begin with one of two special <firstterm>director</firstterm> prefixes.
7186 If an RE begins with <literal>***:</literal>,
7187 the rest of the RE is taken as an ARE. (This normally has no effect in
7188 <productname>PostgreSQL</productname>, since REs are assumed to be AREs;
7189 but it does have an effect if ERE or BRE mode had been specified by
7190 the <replaceable>flags</replaceable> parameter to a regex function.)
7191 If an RE begins with <literal>***=</literal>,
7192 the rest of the RE is taken to be a literal string,
7193 with all characters considered ordinary characters.
7194 </para>
7196 <para>
7197 An ARE can begin with <firstterm>embedded options</firstterm>:
7198 a sequence <literal>(?</literal><replaceable>xyz</replaceable><literal>)</literal>
7199 (where <replaceable>xyz</replaceable> is one or more alphabetic characters)
7200 specifies options affecting the rest of the RE.
7201 These options override any previously determined options &mdash;
7202 in particular, they can override the case-sensitivity behavior implied by
7203 a regex operator, or the <replaceable>flags</replaceable> parameter to a regex
7204 function.
7205 The available option letters are
7206 shown in <xref linkend="posix-embedded-options-table"/>.
7207 Note that these same option letters are used in the <replaceable>flags</replaceable>
7208 parameters of regex functions.
7209 </para>
7211 <table id="posix-embedded-options-table">
7212 <title>ARE Embedded-Option Letters</title>
7214 <tgroup cols="2">
7215 <thead>
7216 <row>
7217 <entry>Option</entry>
7218 <entry>Description</entry>
7219 </row>
7220 </thead>
7222 <tbody>
7223 <row>
7224 <entry> <literal>b</literal> </entry>
7225 <entry> rest of RE is a BRE </entry>
7226 </row>
7228 <row>
7229 <entry> <literal>c</literal> </entry>
7230 <entry> case-sensitive matching (overrides operator type) </entry>
7231 </row>
7233 <row>
7234 <entry> <literal>e</literal> </entry>
7235 <entry> rest of RE is an ERE </entry>
7236 </row>
7238 <row>
7239 <entry> <literal>i</literal> </entry>
7240 <entry> case-insensitive matching (see
7241 <xref linkend="posix-matching-rules"/>) (overrides operator type) </entry>
7242 </row>
7244 <row>
7245 <entry> <literal>m</literal> </entry>
7246 <entry> historical synonym for <literal>n</literal> </entry>
7247 </row>
7249 <row>
7250 <entry> <literal>n</literal> </entry>
7251 <entry> newline-sensitive matching (see
7252 <xref linkend="posix-matching-rules"/>) </entry>
7253 </row>
7255 <row>
7256 <entry> <literal>p</literal> </entry>
7257 <entry> partial newline-sensitive matching (see
7258 <xref linkend="posix-matching-rules"/>) </entry>
7259 </row>
7261 <row>
7262 <entry> <literal>q</literal> </entry>
7263 <entry> rest of RE is a literal (<quote>quoted</quote>) string, all ordinary
7264 characters </entry>
7265 </row>
7267 <row>
7268 <entry> <literal>s</literal> </entry>
7269 <entry> non-newline-sensitive matching (default) </entry>
7270 </row>
7272 <row>
7273 <entry> <literal>t</literal> </entry>
7274 <entry> tight syntax (default; see below) </entry>
7275 </row>
7277 <row>
7278 <entry> <literal>w</literal> </entry>
7279 <entry> inverse partial newline-sensitive (<quote>weird</quote>) matching
7280 (see <xref linkend="posix-matching-rules"/>) </entry>
7281 </row>
7283 <row>
7284 <entry> <literal>x</literal> </entry>
7285 <entry> expanded syntax (see below) </entry>
7286 </row>
7287 </tbody>
7288 </tgroup>
7289 </table>
7291 <para>
7292 Embedded options take effect at the <literal>)</literal> terminating the sequence.
7293 They can appear only at the start of an ARE (after the
7294 <literal>***:</literal> director if any).
7295 </para>
7297 <para>
7298 In addition to the usual (<firstterm>tight</firstterm>) RE syntax, in which all
7299 characters are significant, there is an <firstterm>expanded</firstterm> syntax,
7300 available by specifying the embedded <literal>x</literal> option.
7301 In the expanded syntax,
7302 white-space characters in the RE are ignored, as are
7303 all characters between a <literal>#</literal>
7304 and the following newline (or the end of the RE). This
7305 permits paragraphing and commenting a complex RE.
7306 There are three exceptions to that basic rule:
7308 <itemizedlist>
7309 <listitem>
7310 <para>
7311 a white-space character or <literal>#</literal> preceded by <literal>\</literal> is
7312 retained
7313 </para>
7314 </listitem>
7315 <listitem>
7316 <para>
7317 white space or <literal>#</literal> within a bracket expression is retained
7318 </para>
7319 </listitem>
7320 <listitem>
7321 <para>
7322 white space and comments cannot appear within multi-character symbols,
7323 such as <literal>(?:</literal>
7324 </para>
7325 </listitem>
7326 </itemizedlist>
7328 For this purpose, white-space characters are blank, tab, newline, and
7329 any character that belongs to the <replaceable>space</replaceable> character class.
7330 </para>
7332 <para>
7333 Finally, in an ARE, outside bracket expressions, the sequence
7334 <literal>(?#</literal><replaceable>ttt</replaceable><literal>)</literal>
7335 (where <replaceable>ttt</replaceable> is any text not containing a <literal>)</literal>)
7336 is a comment, completely ignored.
7337 Again, this is not allowed between the characters of
7338 multi-character symbols, like <literal>(?:</literal>.
7339 Such comments are more a historical artifact than a useful facility,
7340 and their use is deprecated; use the expanded syntax instead.
7341 </para>
7343 <para>
7344 <emphasis>None</emphasis> of these metasyntax extensions is available if
7345 an initial <literal>***=</literal> director
7346 has specified that the user's input be treated as a literal string
7347 rather than as an RE.
7348 </para>
7349 </sect3>
7351 <sect3 id="posix-matching-rules">
7352 <title>Regular Expression Matching Rules</title>
7354 <para>
7355 In the event that an RE could match more than one substring of a given
7356 string, the RE matches the one starting earliest in the string.
7357 If the RE could match more than one substring starting at that point,
7358 either the longest possible match or the shortest possible match will
7359 be taken, depending on whether the RE is <firstterm>greedy</firstterm> or
7360 <firstterm>non-greedy</firstterm>.
7361 </para>
7363 <para>
7364 Whether an RE is greedy or not is determined by the following rules:
7365 <itemizedlist>
7366 <listitem>
7367 <para>
7368 Most atoms, and all constraints, have no greediness attribute (because
7369 they cannot match variable amounts of text anyway).
7370 </para>
7371 </listitem>
7372 <listitem>
7373 <para>
7374 Adding parentheses around an RE does not change its greediness.
7375 </para>
7376 </listitem>
7377 <listitem>
7378 <para>
7379 A quantified atom with a fixed-repetition quantifier
7380 (<literal>{</literal><replaceable>m</replaceable><literal>}</literal>
7382 <literal>{</literal><replaceable>m</replaceable><literal>}?</literal>)
7383 has the same greediness (possibly none) as the atom itself.
7384 </para>
7385 </listitem>
7386 <listitem>
7387 <para>
7388 A quantified atom with other normal quantifiers (including
7389 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
7390 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7391 is greedy (prefers longest match).
7392 </para>
7393 </listitem>
7394 <listitem>
7395 <para>
7396 A quantified atom with a non-greedy quantifier (including
7397 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal>
7398 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7399 is non-greedy (prefers shortest match).
7400 </para>
7401 </listitem>
7402 <listitem>
7403 <para>
7404 A branch &mdash; that is, an RE that has no top-level
7405 <literal>|</literal> operator &mdash; has the same greediness as the first
7406 quantified atom in it that has a greediness attribute.
7407 </para>
7408 </listitem>
7409 <listitem>
7410 <para>
7411 An RE consisting of two or more branches connected by the
7412 <literal>|</literal> operator is always greedy.
7413 </para>
7414 </listitem>
7415 </itemizedlist>
7416 </para>
7418 <para>
7419 The above rules associate greediness attributes not only with individual
7420 quantified atoms, but with branches and entire REs that contain quantified
7421 atoms. What that means is that the matching is done in such a way that
7422 the branch, or whole RE, matches the longest or shortest possible
7423 substring <emphasis>as a whole</emphasis>. Once the length of the entire match
7424 is determined, the part of it that matches any particular subexpression
7425 is determined on the basis of the greediness attribute of that
7426 subexpression, with subexpressions starting earlier in the RE taking
7427 priority over ones starting later.
7428 </para>
7430 <para>
7431 An example of what this means:
7432 <screen>
7433 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
7434 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
7435 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
7436 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7437 </screen>
7438 In the first case, the RE as a whole is greedy because <literal>Y*</literal>
7439 is greedy. It can match beginning at the <literal>Y</literal>, and it matches
7440 the longest possible string starting there, i.e., <literal>Y123</literal>.
7441 The output is the parenthesized part of that, or <literal>123</literal>.
7442 In the second case, the RE as a whole is non-greedy because <literal>Y*?</literal>
7443 is non-greedy. It can match beginning at the <literal>Y</literal>, and it matches
7444 the shortest possible string starting there, i.e., <literal>Y1</literal>.
7445 The subexpression <literal>[0-9]{1,3}</literal> is greedy but it cannot change
7446 the decision as to the overall match length; so it is forced to match
7447 just <literal>1</literal>.
7448 </para>
7450 <para>
7451 In short, when an RE contains both greedy and non-greedy subexpressions,
7452 the total match length is either as long as possible or as short as
7453 possible, according to the attribute assigned to the whole RE. The
7454 attributes assigned to the subexpressions only affect how much of that
7455 match they are allowed to <quote>eat</quote> relative to each other.
7456 </para>
7458 <para>
7459 The quantifiers <literal>{1,1}</literal> and <literal>{1,1}?</literal>
7460 can be used to force greediness or non-greediness, respectively,
7461 on a subexpression or a whole RE.
7462 This is useful when you need the whole RE to have a greediness attribute
7463 different from what's deduced from its elements. As an example,
7464 suppose that we are trying to separate a string containing some digits
7465 into the digits and the parts before and after them. We might try to
7466 do that like this:
7467 <screen>
7468 SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
7469 <lineannotation>Result: </lineannotation><computeroutput>{abc0123,4,xyz}</computeroutput>
7470 </screen>
7471 That didn't work: the first <literal>.*</literal> is greedy so
7472 it <quote>eats</quote> as much as it can, leaving the <literal>\d+</literal> to
7473 match at the last possible place, the last digit. We might try to fix
7474 that by making it non-greedy:
7475 <screen>
7476 SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
7477 <lineannotation>Result: </lineannotation><computeroutput>{abc,0,""}</computeroutput>
7478 </screen>
7479 That didn't work either, because now the RE as a whole is non-greedy
7480 and so it ends the overall match as soon as possible. We can get what
7481 we want by forcing the RE as a whole to be greedy:
7482 <screen>
7483 SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
7484 <lineannotation>Result: </lineannotation><computeroutput>{abc,01234,xyz}</computeroutput>
7485 </screen>
7486 Controlling the RE's overall greediness separately from its components'
7487 greediness allows great flexibility in handling variable-length patterns.
7488 </para>
7490 <para>
7491 When deciding what is a longer or shorter match,
7492 match lengths are measured in characters, not collating elements.
7493 An empty string is considered longer than no match at all.
7494 For example:
7495 <literal>bb*</literal>
7496 matches the three middle characters of <literal>abbbc</literal>;
7497 <literal>(week|wee)(night|knights)</literal>
7498 matches all ten characters of <literal>weeknights</literal>;
7499 when <literal>(.*).*</literal>
7500 is matched against <literal>abc</literal> the parenthesized subexpression
7501 matches all three characters; and when
7502 <literal>(a*)*</literal> is matched against <literal>bc</literal>
7503 both the whole RE and the parenthesized
7504 subexpression match an empty string.
7505 </para>
7507 <para>
7508 If case-independent matching is specified,
7509 the effect is much as if all case distinctions had vanished from the
7510 alphabet.
7511 When an alphabetic that exists in multiple cases appears as an
7512 ordinary character outside a bracket expression, it is effectively
7513 transformed into a bracket expression containing both cases,
7514 e.g., <literal>x</literal> becomes <literal>[xX]</literal>.
7515 When it appears inside a bracket expression, all case counterparts
7516 of it are added to the bracket expression, e.g.,
7517 <literal>[x]</literal> becomes <literal>[xX]</literal>
7518 and <literal>[^x]</literal> becomes <literal>[^xX]</literal>.
7519 </para>
7521 <para>
7522 If newline-sensitive matching is specified, <literal>.</literal>
7523 and bracket expressions using <literal>^</literal>
7524 will never match the newline character
7525 (so that matches will not cross lines unless the RE
7526 explicitly includes a newline)
7527 and <literal>^</literal> and <literal>$</literal>
7528 will match the empty string after and before a newline
7529 respectively, in addition to matching at beginning and end of string
7530 respectively.
7531 But the ARE escapes <literal>\A</literal> and <literal>\Z</literal>
7532 continue to match beginning or end of string <emphasis>only</emphasis>.
7533 Also, the character class shorthands <literal>\D</literal>
7534 and <literal>\W</literal> will match a newline regardless of this mode.
7535 (Before <productname>PostgreSQL</productname> 14, they did not match
7536 newlines when in newline-sensitive mode.
7537 Write <literal>[^[:digit:]]</literal>
7538 or <literal>[^[:word:]]</literal> to get the old behavior.)
7539 </para>
7541 <para>
7542 If partial newline-sensitive matching is specified,
7543 this affects <literal>.</literal> and bracket expressions
7544 as with newline-sensitive matching, but not <literal>^</literal>
7545 and <literal>$</literal>.
7546 </para>
7548 <para>
7549 If inverse partial newline-sensitive matching is specified,
7550 this affects <literal>^</literal> and <literal>$</literal>
7551 as with newline-sensitive matching, but not <literal>.</literal>
7552 and bracket expressions.
7553 This isn't very useful but is provided for symmetry.
7554 </para>
7555 </sect3>
7557 <sect3 id="posix-limits-compatibility">
7558 <title>Limits and Compatibility</title>
7560 <para>
7561 No particular limit is imposed on the length of REs in this
7562 implementation. However,
7563 programs intended to be highly portable should not employ REs longer
7564 than 256 bytes,
7565 as a POSIX-compliant implementation can refuse to accept such REs.
7566 </para>
7568 <para>
7569 The only feature of AREs that is actually incompatible with
7570 POSIX EREs is that <literal>\</literal> does not lose its special
7571 significance inside bracket expressions.
7572 All other ARE features use syntax which is illegal or has
7573 undefined or unspecified effects in POSIX EREs;
7574 the <literal>***</literal> syntax of directors likewise is outside the POSIX
7575 syntax for both BREs and EREs.
7576 </para>
7578 <para>
7579 Many of the ARE extensions are borrowed from Perl, but some have
7580 been changed to clean them up, and a few Perl extensions are not present.
7581 Incompatibilities of note include <literal>\b</literal>, <literal>\B</literal>,
7582 the lack of special treatment for a trailing newline,
7583 the addition of complemented bracket expressions to the things
7584 affected by newline-sensitive matching,
7585 the restrictions on parentheses and back references in lookahead/lookbehind
7586 constraints, and the longest/shortest-match (rather than first-match)
7587 matching semantics.
7588 </para>
7589 </sect3>
7591 <sect3 id="posix-basic-regexes">
7592 <title>Basic Regular Expressions</title>
7594 <para>
7595 BREs differ from EREs in several respects.
7596 In BREs, <literal>|</literal>, <literal>+</literal>, and <literal>?</literal>
7597 are ordinary characters and there is no equivalent
7598 for their functionality.
7599 The delimiters for bounds are
7600 <literal>\{</literal> and <literal>\}</literal>,
7601 with <literal>{</literal> and <literal>}</literal>
7602 by themselves ordinary characters.
7603 The parentheses for nested subexpressions are
7604 <literal>\(</literal> and <literal>\)</literal>,
7605 with <literal>(</literal> and <literal>)</literal> by themselves ordinary characters.
7606 <literal>^</literal> is an ordinary character except at the beginning of the
7607 RE or the beginning of a parenthesized subexpression,
7608 <literal>$</literal> is an ordinary character except at the end of the
7609 RE or the end of a parenthesized subexpression,
7610 and <literal>*</literal> is an ordinary character if it appears at the beginning
7611 of the RE or the beginning of a parenthesized subexpression
7612 (after a possible leading <literal>^</literal>).
7613 Finally, single-digit back references are available, and
7614 <literal>\&lt;</literal> and <literal>\&gt;</literal>
7615 are synonyms for
7616 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal>
7617 respectively; no other escapes are available in BREs.
7618 </para>
7619 </sect3>
7621 <!-- end re_syntax.n man page -->
7623 <sect3 id="posix-vs-xquery">
7624 <title>Differences from SQL Standard and XQuery</title>
7626 <indexterm zone="posix-vs-xquery">
7627 <primary>LIKE_REGEX</primary>
7628 </indexterm>
7630 <indexterm zone="posix-vs-xquery">
7631 <primary>OCCURRENCES_REGEX</primary>
7632 </indexterm>
7634 <indexterm zone="posix-vs-xquery">
7635 <primary>POSITION_REGEX</primary>
7636 </indexterm>
7638 <indexterm zone="posix-vs-xquery">
7639 <primary>SUBSTRING_REGEX</primary>
7640 </indexterm>
7642 <indexterm zone="posix-vs-xquery">
7643 <primary>TRANSLATE_REGEX</primary>
7644 </indexterm>
7646 <indexterm zone="posix-vs-xquery">
7647 <primary>XQuery regular expressions</primary>
7648 </indexterm>
7650 <para>
7651 Since SQL:2008, the SQL standard includes regular expression operators
7652 and functions that performs pattern
7653 matching according to the XQuery regular expression
7654 standard:
7655 <itemizedlist>
7656 <listitem><para><literal>LIKE_REGEX</literal></para></listitem>
7657 <listitem><para><literal>OCCURRENCES_REGEX</literal></para></listitem>
7658 <listitem><para><literal>POSITION_REGEX</literal></para></listitem>
7659 <listitem><para><literal>SUBSTRING_REGEX</literal></para></listitem>
7660 <listitem><para><literal>TRANSLATE_REGEX</literal></para></listitem>
7661 </itemizedlist>
7662 <productname>PostgreSQL</productname> does not currently implement these
7663 operators and functions. You can get approximately equivalent
7664 functionality in each case as shown in <xref
7665 linkend="functions-regexp-sql-table"/>. (Various optional clauses on
7666 both sides have been omitted in this table.)
7667 </para>
7669 <table id="functions-regexp-sql-table">
7670 <title>Regular Expression Functions Equivalencies</title>
7672 <tgroup cols="2">
7673 <thead>
7674 <row>
7675 <entry>SQL standard</entry>
7676 <entry><productname>PostgreSQL</productname></entry>
7677 </row>
7678 </thead>
7680 <tbody>
7681 <row>
7682 <entry><literal><replaceable>string</replaceable> LIKE_REGEX <replaceable>pattern</replaceable></literal></entry>
7683 <entry><literal>regexp_like(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal> or <literal><replaceable>string</replaceable> ~ <replaceable>pattern</replaceable></literal></entry>
7684 </row>
7686 <row>
7687 <entry><literal>OCCURRENCES_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7688 <entry><literal>regexp_count(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7689 </row>
7691 <row>
7692 <entry><literal>POSITION_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7693 <entry><literal>regexp_instr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7694 </row>
7696 <row>
7697 <entry><literal>SUBSTRING_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7698 <entry><literal>regexp_substr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7699 </row>
7701 <row>
7702 <entry><literal>TRANSLATE_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable> WITH <replaceable>replacement</replaceable>)</literal></entry>
7703 <entry><literal>regexp_replace(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>)</literal></entry>
7704 </row>
7705 </tbody>
7706 </tgroup>
7707 </table>
7709 <para>
7710 Regular expression functions similar to those provided by PostgreSQL are
7711 also available in a number of other SQL implementations, whereas the
7712 SQL-standard functions are not as widely implemented. Some of the
7713 details of the regular expression syntax will likely differ in each
7714 implementation.
7715 </para>
7717 <para>
7718 The SQL-standard operators and functions use XQuery regular expressions,
7719 which are quite close to the ARE syntax described above.
7720 Notable differences between the existing POSIX-based
7721 regular-expression feature and XQuery regular expressions include:
7723 <itemizedlist>
7724 <listitem>
7725 <para>
7726 XQuery character class subtraction is not supported. An example of
7727 this feature is using the following to match only English
7728 consonants: <literal>[a-z-[aeiou]]</literal>.
7729 </para>
7730 </listitem>
7731 <listitem>
7732 <para>
7733 XQuery character class shorthands <literal>\c</literal>,
7734 <literal>\C</literal>, <literal>\i</literal>,
7735 and <literal>\I</literal> are not supported.
7736 </para>
7737 </listitem>
7738 <listitem>
7739 <para>
7740 XQuery character class elements
7741 using <literal>\p{UnicodeProperty}</literal> or the
7742 inverse <literal>\P{UnicodeProperty}</literal> are not supported.
7743 </para>
7744 </listitem>
7745 <listitem>
7746 <para>
7747 POSIX interprets character classes such as <literal>\w</literal>
7748 (see <xref linkend="posix-class-shorthand-escapes-table"/>)
7749 according to the prevailing locale (which you can control by
7750 attaching a <literal>COLLATE</literal> clause to the operator or
7751 function). XQuery specifies these classes by reference to Unicode
7752 character properties, so equivalent behavior is obtained only with
7753 a locale that follows the Unicode rules.
7754 </para>
7755 </listitem>
7756 <listitem>
7757 <para>
7758 The SQL standard (not XQuery itself) attempts to cater for more
7759 variants of <quote>newline</quote> than POSIX does. The
7760 newline-sensitive matching options described above consider only
7761 ASCII NL (<literal>\n</literal>) to be a newline, but SQL would have
7762 us treat CR (<literal>\r</literal>), CRLF (<literal>\r\n</literal>)
7763 (a Windows-style newline), and some Unicode-only characters like
7764 LINE SEPARATOR (U+2028) as newlines as well.
7765 Notably, <literal>.</literal> and <literal>\s</literal> should
7766 count <literal>\r\n</literal> as one character not two according to
7767 SQL.
7768 </para>
7769 </listitem>
7770 <listitem>
7771 <para>
7772 Of the character-entry escapes described in
7773 <xref linkend="posix-character-entry-escapes-table"/>,
7774 XQuery supports only <literal>\n</literal>, <literal>\r</literal>,
7775 and <literal>\t</literal>.
7776 </para>
7777 </listitem>
7778 <listitem>
7779 <para>
7780 XQuery does not support
7781 the <literal>[:<replaceable>name</replaceable>:]</literal> syntax
7782 for character classes within bracket expressions.
7783 </para>
7784 </listitem>
7785 <listitem>
7786 <para>
7787 XQuery does not have lookahead or lookbehind constraints,
7788 nor any of the constraint escapes described in
7789 <xref linkend="posix-constraint-escapes-table"/>.
7790 </para>
7791 </listitem>
7792 <listitem>
7793 <para>
7794 The metasyntax forms described in <xref linkend="posix-metasyntax"/>
7795 do not exist in XQuery.
7796 </para>
7797 </listitem>
7798 <listitem>
7799 <para>
7800 The regular expression flag letters defined by XQuery are
7801 related to but not the same as the option letters for POSIX
7802 (<xref linkend="posix-embedded-options-table"/>). While the
7803 <literal>i</literal> and <literal>q</literal> options behave the
7804 same, others do not:
7805 <itemizedlist>
7806 <listitem>
7807 <para>
7808 XQuery's <literal>s</literal> (allow dot to match newline)
7809 and <literal>m</literal> (allow <literal>^</literal>
7810 and <literal>$</literal> to match at newlines) flags provide
7811 access to the same behaviors as
7812 POSIX's <literal>n</literal>, <literal>p</literal>
7813 and <literal>w</literal> flags, but they
7814 do <emphasis>not</emphasis> match the behavior of
7815 POSIX's <literal>s</literal> and <literal>m</literal> flags.
7816 Note in particular that dot-matches-newline is the default
7817 behavior in POSIX but not XQuery.
7818 </para>
7819 </listitem>
7820 <listitem>
7821 <para>
7822 XQuery's <literal>x</literal> (ignore whitespace in pattern) flag
7823 is noticeably different from POSIX's expanded-mode flag.
7824 POSIX's <literal>x</literal> flag also
7825 allows <literal>#</literal> to begin a comment in the pattern,
7826 and POSIX will not ignore a whitespace character after a
7827 backslash.
7828 </para>
7829 </listitem>
7830 </itemizedlist>
7831 </para>
7832 </listitem>
7833 </itemizedlist>
7834 </para>
7836 </sect3>
7837 </sect2>
7838 </sect1>
7841 <sect1 id="functions-formatting">
7842 <title>Data Type Formatting Functions</title>
7844 <indexterm>
7845 <primary>formatting</primary>
7846 </indexterm>
7848 <para>
7849 The <productname>PostgreSQL</productname> formatting functions
7850 provide a powerful set of tools for converting various data types
7851 (date/time, integer, floating point, numeric) to formatted strings
7852 and for converting from formatted strings to specific data types.
7853 <xref linkend="functions-formatting-table"/> lists them.
7854 These functions all follow a common calling convention: the first
7855 argument is the value to be formatted and the second argument is a
7856 template that defines the output or input format.
7857 </para>
7859 <table id="functions-formatting-table">
7860 <title>Formatting Functions</title>
7861 <tgroup cols="1">
7862 <thead>
7863 <row>
7864 <entry role="func_table_entry"><para role="func_signature">
7865 Function
7866 </para>
7867 <para>
7868 Description
7869 </para>
7870 <para>
7871 Example(s)
7872 </para></entry>
7873 </row>
7874 </thead>
7876 <tbody>
7877 <row>
7878 <entry role="func_table_entry"><para role="func_signature">
7879 <indexterm>
7880 <primary>to_char</primary>
7881 </indexterm>
7882 <function>to_char</function> ( <type>timestamp</type>, <type>text</type> )
7883 <returnvalue>text</returnvalue>
7884 </para>
7885 <para role="func_signature">
7886 <function>to_char</function> ( <type>timestamp with time zone</type>, <type>text</type> )
7887 <returnvalue>text</returnvalue>
7888 </para>
7889 <para>
7890 Converts time stamp to string according to the given format.
7891 </para>
7892 <para>
7893 <literal>to_char(timestamp '2002-04-20 17:31:12.66', 'HH12:MI:SS')</literal>
7894 <returnvalue>05:31:12</returnvalue>
7895 </para></entry>
7896 </row>
7898 <row>
7899 <entry role="func_table_entry"><para role="func_signature">
7900 <function>to_char</function> ( <type>interval</type>, <type>text</type> )
7901 <returnvalue>text</returnvalue>
7902 </para>
7903 <para>
7904 Converts interval to string according to the given format.
7905 </para>
7906 <para>
7907 <literal>to_char(interval '15h 2m 12s', 'HH24:MI:SS')</literal>
7908 <returnvalue>15:02:12</returnvalue>
7909 </para></entry>
7910 </row>
7912 <row>
7913 <entry role="func_table_entry"><para role="func_signature">
7914 <function>to_char</function> ( <replaceable>numeric_type</replaceable>, <type>text</type> )
7915 <returnvalue>text</returnvalue>
7916 </para>
7917 <para>
7918 Converts number to string according to the given format; available
7919 for <type>integer</type>, <type>bigint</type>, <type>numeric</type>,
7920 <type>real</type>, <type>double precision</type>.
7921 </para>
7922 <para>
7923 <literal>to_char(125, '999')</literal>
7924 <returnvalue>125</returnvalue>
7925 </para>
7926 <para>
7927 <literal>to_char(125.8::real, '999D9')</literal>
7928 <returnvalue>125.8</returnvalue>
7929 </para>
7930 <para>
7931 <literal>to_char(-125.8, '999D99S')</literal>
7932 <returnvalue>125.80-</returnvalue>
7933 </para></entry>
7934 </row>
7936 <row>
7937 <entry role="func_table_entry"><para role="func_signature">
7938 <indexterm>
7939 <primary>to_date</primary>
7940 </indexterm>
7941 <function>to_date</function> ( <type>text</type>, <type>text</type> )
7942 <returnvalue>date</returnvalue>
7943 </para>
7944 <para>
7945 Converts string to date according to the given format.
7946 </para>
7947 <para>
7948 <literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal>
7949 <returnvalue>2000-12-05</returnvalue>
7950 </para></entry>
7951 </row>
7953 <row>
7954 <entry role="func_table_entry"><para role="func_signature">
7955 <indexterm>
7956 <primary>to_number</primary>
7957 </indexterm>
7958 <function>to_number</function> ( <type>text</type>, <type>text</type> )
7959 <returnvalue>numeric</returnvalue>
7960 </para>
7961 <para>
7962 Converts string to numeric according to the given format.
7963 </para>
7964 <para>
7965 <literal>to_number('12,454.8-', '99G999D9S')</literal>
7966 <returnvalue>-12454.8</returnvalue>
7967 </para></entry>
7968 </row>
7970 <row>
7971 <entry role="func_table_entry"><para role="func_signature">
7972 <indexterm>
7973 <primary>to_timestamp</primary>
7974 </indexterm>
7975 <function>to_timestamp</function> ( <type>text</type>, <type>text</type> )
7976 <returnvalue>timestamp with time zone</returnvalue>
7977 </para>
7978 <para>
7979 Converts string to time stamp according to the given format.
7980 (See also <function>to_timestamp(double precision)</function> in
7981 <xref linkend="functions-datetime-table"/>.)
7982 </para>
7983 <para>
7984 <literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal>
7985 <returnvalue>2000-12-05 00:00:00-05</returnvalue>
7986 </para></entry>
7987 </row>
7988 </tbody>
7989 </tgroup>
7990 </table>
7992 <tip>
7993 <para>
7994 <function>to_timestamp</function> and <function>to_date</function>
7995 exist to handle input formats that cannot be converted by
7996 simple casting. For most standard date/time formats, simply casting the
7997 source string to the required data type works, and is much easier.
7998 Similarly, <function>to_number</function> is unnecessary for standard numeric
7999 representations.
8000 </para>
8001 </tip>
8003 <para>
8004 In a <function>to_char</function> output template string, there are certain
8005 patterns that are recognized and replaced with appropriately-formatted
8006 data based on the given value. Any text that is not a template pattern is
8007 simply copied verbatim. Similarly, in an input template string (for the
8008 other functions), template patterns identify the values to be supplied by
8009 the input data string. If there are characters in the template string
8010 that are not template patterns, the corresponding characters in the input
8011 data string are simply skipped over (whether or not they are equal to the
8012 template string characters).
8013 </para>
8015 <para>
8016 <xref linkend="functions-formatting-datetime-table"/> shows the
8017 template patterns available for formatting date and time values.
8018 </para>
8020 <table id="functions-formatting-datetime-table">
8021 <title>Template Patterns for Date/Time Formatting</title>
8022 <tgroup cols="2">
8023 <thead>
8024 <row>
8025 <entry>Pattern</entry>
8026 <entry>Description</entry>
8027 </row>
8028 </thead>
8029 <tbody>
8030 <row>
8031 <entry><literal>HH</literal></entry>
8032 <entry>hour of day (01&ndash;12)</entry>
8033 </row>
8034 <row>
8035 <entry><literal>HH12</literal></entry>
8036 <entry>hour of day (01&ndash;12)</entry>
8037 </row>
8038 <row>
8039 <entry><literal>HH24</literal></entry>
8040 <entry>hour of day (00&ndash;23)</entry>
8041 </row>
8042 <row>
8043 <entry><literal>MI</literal></entry>
8044 <entry>minute (00&ndash;59)</entry>
8045 </row>
8046 <row>
8047 <entry><literal>SS</literal></entry>
8048 <entry>second (00&ndash;59)</entry>
8049 </row>
8050 <row>
8051 <entry><literal>MS</literal></entry>
8052 <entry>millisecond (000&ndash;999)</entry>
8053 </row>
8054 <row>
8055 <entry><literal>US</literal></entry>
8056 <entry>microsecond (000000&ndash;999999)</entry>
8057 </row>
8058 <row>
8059 <entry><literal>FF1</literal></entry>
8060 <entry>tenth of second (0&ndash;9)</entry>
8061 </row>
8062 <row>
8063 <entry><literal>FF2</literal></entry>
8064 <entry>hundredth of second (00&ndash;99)</entry>
8065 </row>
8066 <row>
8067 <entry><literal>FF3</literal></entry>
8068 <entry>millisecond (000&ndash;999)</entry>
8069 </row>
8070 <row>
8071 <entry><literal>FF4</literal></entry>
8072 <entry>tenth of a millisecond (0000&ndash;9999)</entry>
8073 </row>
8074 <row>
8075 <entry><literal>FF5</literal></entry>
8076 <entry>hundredth of a millisecond (00000&ndash;99999)</entry>
8077 </row>
8078 <row>
8079 <entry><literal>FF6</literal></entry>
8080 <entry>microsecond (000000&ndash;999999)</entry>
8081 </row>
8082 <row>
8083 <entry><literal>SSSS</literal>, <literal>SSSSS</literal></entry>
8084 <entry>seconds past midnight (0&ndash;86399)</entry>
8085 </row>
8086 <row>
8087 <entry><literal>AM</literal>, <literal>am</literal>,
8088 <literal>PM</literal> or <literal>pm</literal></entry>
8089 <entry>meridiem indicator (without periods)</entry>
8090 </row>
8091 <row>
8092 <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
8093 <literal>P.M.</literal> or <literal>p.m.</literal></entry>
8094 <entry>meridiem indicator (with periods)</entry>
8095 </row>
8096 <row>
8097 <entry><literal>Y,YYY</literal></entry>
8098 <entry>year (4 or more digits) with comma</entry>
8099 </row>
8100 <row>
8101 <entry><literal>YYYY</literal></entry>
8102 <entry>year (4 or more digits)</entry>
8103 </row>
8104 <row>
8105 <entry><literal>YYY</literal></entry>
8106 <entry>last 3 digits of year</entry>
8107 </row>
8108 <row>
8109 <entry><literal>YY</literal></entry>
8110 <entry>last 2 digits of year</entry>
8111 </row>
8112 <row>
8113 <entry><literal>Y</literal></entry>
8114 <entry>last digit of year</entry>
8115 </row>
8116 <row>
8117 <entry><literal>IYYY</literal></entry>
8118 <entry>ISO 8601 week-numbering year (4 or more digits)</entry>
8119 </row>
8120 <row>
8121 <entry><literal>IYY</literal></entry>
8122 <entry>last 3 digits of ISO 8601 week-numbering year</entry>
8123 </row>
8124 <row>
8125 <entry><literal>IY</literal></entry>
8126 <entry>last 2 digits of ISO 8601 week-numbering year</entry>
8127 </row>
8128 <row>
8129 <entry><literal>I</literal></entry>
8130 <entry>last digit of ISO 8601 week-numbering year</entry>
8131 </row>
8132 <row>
8133 <entry><literal>BC</literal>, <literal>bc</literal>,
8134 <literal>AD</literal> or <literal>ad</literal></entry>
8135 <entry>era indicator (without periods)</entry>
8136 </row>
8137 <row>
8138 <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
8139 <literal>A.D.</literal> or <literal>a.d.</literal></entry>
8140 <entry>era indicator (with periods)</entry>
8141 </row>
8142 <row>
8143 <entry><literal>MONTH</literal></entry>
8144 <entry>full upper case month name (blank-padded to 9 chars)</entry>
8145 </row>
8146 <row>
8147 <entry><literal>Month</literal></entry>
8148 <entry>full capitalized month name (blank-padded to 9 chars)</entry>
8149 </row>
8150 <row>
8151 <entry><literal>month</literal></entry>
8152 <entry>full lower case month name (blank-padded to 9 chars)</entry>
8153 </row>
8154 <row>
8155 <entry><literal>MON</literal></entry>
8156 <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
8157 </row>
8158 <row>
8159 <entry><literal>Mon</literal></entry>
8160 <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
8161 </row>
8162 <row>
8163 <entry><literal>mon</literal></entry>
8164 <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
8165 </row>
8166 <row>
8167 <entry><literal>MM</literal></entry>
8168 <entry>month number (01&ndash;12)</entry>
8169 </row>
8170 <row>
8171 <entry><literal>DAY</literal></entry>
8172 <entry>full upper case day name (blank-padded to 9 chars)</entry>
8173 </row>
8174 <row>
8175 <entry><literal>Day</literal></entry>
8176 <entry>full capitalized day name (blank-padded to 9 chars)</entry>
8177 </row>
8178 <row>
8179 <entry><literal>day</literal></entry>
8180 <entry>full lower case day name (blank-padded to 9 chars)</entry>
8181 </row>
8182 <row>
8183 <entry><literal>DY</literal></entry>
8184 <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
8185 </row>
8186 <row>
8187 <entry><literal>Dy</literal></entry>
8188 <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
8189 </row>
8190 <row>
8191 <entry><literal>dy</literal></entry>
8192 <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
8193 </row>
8194 <row>
8195 <entry><literal>DDD</literal></entry>
8196 <entry>day of year (001&ndash;366)</entry>
8197 </row>
8198 <row>
8199 <entry><literal>IDDD</literal></entry>
8200 <entry>day of ISO 8601 week-numbering year (001&ndash;371; day 1 of the year is Monday of the first ISO week)</entry>
8201 </row>
8202 <row>
8203 <entry><literal>DD</literal></entry>
8204 <entry>day of month (01&ndash;31)</entry>
8205 </row>
8206 <row>
8207 <entry><literal>D</literal></entry>
8208 <entry>day of the week, Sunday (<literal>1</literal>) to Saturday (<literal>7</literal>)</entry>
8209 </row>
8210 <row>
8211 <entry><literal>ID</literal></entry>
8212 <entry>ISO 8601 day of the week, Monday (<literal>1</literal>) to Sunday (<literal>7</literal>)</entry>
8213 </row>
8214 <row>
8215 <entry><literal>W</literal></entry>
8216 <entry>week of month (1&ndash;5) (the first week starts on the first day of the month)</entry>
8217 </row>
8218 <row>
8219 <entry><literal>WW</literal></entry>
8220 <entry>week number of year (1&ndash;53) (the first week starts on the first day of the year)</entry>
8221 </row>
8222 <row>
8223 <entry><literal>IW</literal></entry>
8224 <entry>week number of ISO 8601 week-numbering year (01&ndash;53; the first Thursday of the year is in week 1)</entry>
8225 </row>
8226 <row>
8227 <entry><literal>CC</literal></entry>
8228 <entry>century (2 digits) (the twenty-first century starts on 2001-01-01)</entry>
8229 </row>
8230 <row>
8231 <entry><literal>J</literal></entry>
8232 <entry>Julian Date (integer days since November 24, 4714 BC at local
8233 midnight; see <xref linkend="datetime-julian-dates"/>)</entry>
8234 </row>
8235 <row>
8236 <entry><literal>Q</literal></entry>
8237 <entry>quarter</entry>
8238 </row>
8239 <row>
8240 <entry><literal>RM</literal></entry>
8241 <entry>month in upper case Roman numerals (I&ndash;XII; I=January)</entry>
8242 </row>
8243 <row>
8244 <entry><literal>rm</literal></entry>
8245 <entry>month in lower case Roman numerals (i&ndash;xii; i=January)</entry>
8246 </row>
8247 <row>
8248 <entry><literal>TZ</literal></entry>
8249 <entry>upper case time-zone abbreviation</entry>
8250 </row>
8251 <row>
8252 <entry><literal>tz</literal></entry>
8253 <entry>lower case time-zone abbreviation</entry>
8254 </row>
8255 <row>
8256 <entry><literal>TZH</literal></entry>
8257 <entry>time-zone hours</entry>
8258 </row>
8259 <row>
8260 <entry><literal>TZM</literal></entry>
8261 <entry>time-zone minutes</entry>
8262 </row>
8263 <row>
8264 <entry><literal>OF</literal></entry>
8265 <entry>time-zone offset from UTC (<replaceable>HH</replaceable>
8266 or <replaceable>HH</replaceable><literal>:</literal><replaceable>MM</replaceable>)</entry>
8267 </row>
8268 </tbody>
8269 </tgroup>
8270 </table>
8272 <para>
8273 Modifiers can be applied to any template pattern to alter its
8274 behavior. For example, <literal>FMMonth</literal>
8275 is the <literal>Month</literal> pattern with the
8276 <literal>FM</literal> modifier.
8277 <xref linkend="functions-formatting-datetimemod-table"/> shows the
8278 modifier patterns for date/time formatting.
8279 </para>
8281 <table id="functions-formatting-datetimemod-table">
8282 <title>Template Pattern Modifiers for Date/Time Formatting</title>
8283 <tgroup cols="3">
8284 <thead>
8285 <row>
8286 <entry>Modifier</entry>
8287 <entry>Description</entry>
8288 <entry>Example</entry>
8289 </row>
8290 </thead>
8291 <tbody>
8292 <row>
8293 <entry><literal>FM</literal> prefix</entry>
8294 <entry>fill mode (suppress leading zeroes and padding blanks)</entry>
8295 <entry><literal>FMMonth</literal></entry>
8296 </row>
8297 <row>
8298 <entry><literal>TH</literal> suffix</entry>
8299 <entry>upper case ordinal number suffix</entry>
8300 <entry><literal>DDTH</literal>, e.g., <literal>12TH</literal></entry>
8301 </row>
8302 <row>
8303 <entry><literal>th</literal> suffix</entry>
8304 <entry>lower case ordinal number suffix</entry>
8305 <entry><literal>DDth</literal>, e.g., <literal>12th</literal></entry>
8306 </row>
8307 <row>
8308 <entry><literal>FX</literal> prefix</entry>
8309 <entry>fixed format global option (see usage notes)</entry>
8310 <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
8311 </row>
8312 <row>
8313 <entry><literal>TM</literal> prefix</entry>
8314 <entry>translation mode (use localized day and month names based on
8315 <xref linkend="guc-lc-time"/>)</entry>
8316 <entry><literal>TMMonth</literal></entry>
8317 </row>
8318 <row>
8319 <entry><literal>SP</literal> suffix</entry>
8320 <entry>spell mode (not implemented)</entry>
8321 <entry><literal>DDSP</literal></entry>
8322 </row>
8323 </tbody>
8324 </tgroup>
8325 </table>
8327 <para>
8328 Usage notes for date/time formatting:
8330 <itemizedlist>
8331 <listitem>
8332 <para>
8333 <literal>FM</literal> suppresses leading zeroes and trailing blanks
8334 that would otherwise be added to make the output of a pattern be
8335 fixed-width. In <productname>PostgreSQL</productname>,
8336 <literal>FM</literal> modifies only the next specification, while in
8337 Oracle <literal>FM</literal> affects all subsequent
8338 specifications, and repeated <literal>FM</literal> modifiers
8339 toggle fill mode on and off.
8340 </para>
8341 </listitem>
8343 <listitem>
8344 <para>
8345 <literal>TM</literal> suppresses trailing blanks whether or
8346 not <literal>FM</literal> is specified.
8347 </para>
8348 </listitem>
8350 <listitem>
8351 <para>
8352 <function>to_timestamp</function> and <function>to_date</function>
8353 ignore letter case in the input; so for
8354 example <literal>MON</literal>, <literal>Mon</literal>,
8355 and <literal>mon</literal> all accept the same strings. When using
8356 the <literal>TM</literal> modifier, case-folding is done according to
8357 the rules of the function's input collation (see
8358 <xref linkend="collation"/>).
8359 </para>
8360 </listitem>
8362 <listitem>
8363 <para>
8364 <function>to_timestamp</function> and <function>to_date</function>
8365 skip multiple blank spaces at the beginning of the input string and
8366 around date and time values unless the <literal>FX</literal> option is used. For example,
8367 <literal>to_timestamp('&nbsp;2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> and
8368 <literal>to_timestamp('2000 - JUN', 'YYYY-MON')</literal> work, but
8369 <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
8370 because <function>to_timestamp</function> expects only a single space.
8371 <literal>FX</literal> must be specified as the first item in
8372 the template.
8373 </para>
8374 </listitem>
8376 <listitem>
8377 <para>
8378 A separator (a space or non-letter/non-digit character) in the template string of
8379 <function>to_timestamp</function> and <function>to_date</function>
8380 matches any single separator in the input string or is skipped,
8381 unless the <literal>FX</literal> option is used.
8382 For example, <literal>to_timestamp('2000JUN', 'YYYY///MON')</literal> and
8383 <literal>to_timestamp('2000/JUN', 'YYYY MON')</literal> work, but
8384 <literal>to_timestamp('2000//JUN', 'YYYY/MON')</literal>
8385 returns an error because the number of separators in the input string
8386 exceeds the number of separators in the template.
8387 </para>
8388 <para>
8389 If <literal>FX</literal> is specified, a separator in the template string
8390 matches exactly one character in the input string. But note that the
8391 input string character is not required to be the same as the separator from the template string.
8392 For example, <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal>
8393 works, but <literal>to_timestamp('2000/JUN', 'FXYYYY&nbsp;&nbsp;MON')</literal>
8394 returns an error because the second space in the template string consumes
8395 the letter <literal>J</literal> from the input string.
8396 </para>
8397 </listitem>
8399 <listitem>
8400 <para>
8401 A <literal>TZH</literal> template pattern can match a signed number.
8402 Without the <literal>FX</literal> option, minus signs may be ambiguous,
8403 and could be interpreted as a separator.
8404 This ambiguity is resolved as follows: If the number of separators before
8405 <literal>TZH</literal> in the template string is less than the number of
8406 separators before the minus sign in the input string, the minus sign
8407 is interpreted as part of <literal>TZH</literal>.
8408 Otherwise, the minus sign is considered to be a separator between values.
8409 For example, <literal>to_timestamp('2000 -10', 'YYYY TZH')</literal> matches
8410 <literal>-10</literal> to <literal>TZH</literal>, but
8411 <literal>to_timestamp('2000 -10', 'YYYY&nbsp;&nbsp;TZH')</literal>
8412 matches <literal>10</literal> to <literal>TZH</literal>.
8413 </para>
8414 </listitem>
8416 <listitem>
8417 <para>
8418 Ordinary text is allowed in <function>to_char</function>
8419 templates and will be output literally. You can put a substring
8420 in double quotes to force it to be interpreted as literal text
8421 even if it contains template patterns. For example, in
8422 <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
8423 will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
8424 will not be.
8425 In <function>to_date</function>, <function>to_number</function>,
8426 and <function>to_timestamp</function>, literal text and double-quoted
8427 strings result in skipping the number of characters contained in the
8428 string; for example <literal>"XX"</literal> skips two input characters
8429 (whether or not they are <literal>XX</literal>).
8430 </para>
8431 <tip>
8432 <para>
8433 Prior to <productname>PostgreSQL</productname> 12, it was possible to
8434 skip arbitrary text in the input string using non-letter or non-digit
8435 characters. For example,
8436 <literal>to_timestamp('2000y6m1d', 'yyyy-MM-DD')</literal> used to
8437 work. Now you can only use letter characters for this purpose. For example,
8438 <literal>to_timestamp('2000y6m1d', 'yyyytMMtDDt')</literal> and
8439 <literal>to_timestamp('2000y6m1d', 'yyyy"y"MM"m"DD"d"')</literal>
8440 skip <literal>y</literal>, <literal>m</literal>, and
8441 <literal>d</literal>.
8442 </para>
8443 </tip>
8444 </listitem>
8446 <listitem>
8447 <para>
8448 If you want to have a double quote in the output you must
8449 precede it with a backslash, for example <literal>'\"YYYY
8450 Month\"'</literal>. <!-- "" font-lock sanity :-) -->
8451 Backslashes are not otherwise special outside of double-quoted
8452 strings. Within a double-quoted string, a backslash causes the
8453 next character to be taken literally, whatever it is (but this
8454 has no special effect unless the next character is a double quote
8455 or another backslash).
8456 </para>
8457 </listitem>
8459 <listitem>
8460 <para>
8461 In <function>to_timestamp</function> and <function>to_date</function>,
8462 if the year format specification is less than four digits, e.g.,
8463 <literal>YYY</literal>, and the supplied year is less than four digits,
8464 the year will be adjusted to be nearest to the year 2020, e.g.,
8465 <literal>95</literal> becomes 1995.
8466 </para>
8467 </listitem>
8469 <listitem>
8470 <para>
8471 In <function>to_timestamp</function> and <function>to_date</function>,
8472 negative years are treated as signifying BC. If you write both a
8473 negative year and an explicit <literal>BC</literal> field, you get AD
8474 again. An input of year zero is treated as 1 BC.
8475 </para>
8476 </listitem>
8478 <listitem>
8479 <para>
8480 In <function>to_timestamp</function> and <function>to_date</function>,
8481 the <literal>YYYY</literal> conversion has a restriction when
8482 processing years with more than 4 digits. You must
8483 use some non-digit character or template after <literal>YYYY</literal>,
8484 otherwise the year is always interpreted as 4 digits. For example
8485 (with the year 20000):
8486 <literal>to_date('200001130', 'YYYYMMDD')</literal> will be
8487 interpreted as a 4-digit year; instead use a non-digit
8488 separator after the year, like
8489 <literal>to_date('20000-1130', 'YYYY-MMDD')</literal> or
8490 <literal>to_date('20000Nov30', 'YYYYMonDD')</literal>.
8491 </para>
8492 </listitem>
8494 <listitem>
8495 <para>
8496 In <function>to_timestamp</function> and <function>to_date</function>,
8497 the <literal>CC</literal> (century) field is accepted but ignored
8498 if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
8499 <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
8500 <literal>YY</literal> or <literal>Y</literal> then the result is
8501 computed as that year in the specified century. If the century is
8502 specified but the year is not, the first year of the century
8503 is assumed.
8504 </para>
8505 </listitem>
8507 <listitem>
8508 <para>
8509 In <function>to_timestamp</function> and <function>to_date</function>,
8510 weekday names or numbers (<literal>DAY</literal>, <literal>D</literal>,
8511 and related field types) are accepted but are ignored for purposes of
8512 computing the result. The same is true for quarter
8513 (<literal>Q</literal>) fields.
8514 </para>
8515 </listitem>
8517 <listitem>
8518 <para>
8519 In <function>to_timestamp</function> and <function>to_date</function>,
8520 an ISO 8601 week-numbering date (as distinct from a Gregorian date)
8521 can be specified in one of two ways:
8522 <itemizedlist>
8523 <listitem>
8524 <para>
8525 Year, week number, and weekday: for
8526 example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal>
8527 returns the date <literal>2006-10-19</literal>.
8528 If you omit the weekday it is assumed to be 1 (Monday).
8529 </para>
8530 </listitem>
8531 <listitem>
8532 <para>
8533 Year and day of year: for example <literal>to_date('2006-291',
8534 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
8535 </para>
8536 </listitem>
8537 </itemizedlist>
8538 </para>
8539 <para>
8540 Attempting to enter a date using a mixture of ISO 8601 week-numbering
8541 fields and Gregorian date fields is nonsensical, and will cause an
8542 error. In the context of an ISO 8601 week-numbering year, the
8543 concept of a <quote>month</quote> or <quote>day of month</quote> has no
8544 meaning. In the context of a Gregorian year, the ISO week has no
8545 meaning.
8546 </para>
8547 <caution>
8548 <para>
8549 While <function>to_date</function> will reject a mixture of
8550 Gregorian and ISO week-numbering date
8551 fields, <function>to_char</function> will not, since output format
8552 specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</literal> can be
8553 useful. But avoid writing something like <literal>IYYY-MM-DD</literal>;
8554 that would yield surprising results near the start of the year.
8555 (See <xref linkend="functions-datetime-extract"/> for more
8556 information.)
8557 </para>
8558 </caution>
8559 </listitem>
8561 <listitem>
8562 <para>
8563 In <function>to_timestamp</function>, millisecond
8564 (<literal>MS</literal>) or microsecond (<literal>US</literal>)
8565 fields are used as the
8566 seconds digits after the decimal point. For example
8567 <literal>to_timestamp('12.3', 'SS.MS')</literal> is not 3 milliseconds,
8568 but 300, because the conversion treats it as 12 + 0.3 seconds.
8569 So, for the format <literal>SS.MS</literal>, the input values
8570 <literal>12.3</literal>, <literal>12.30</literal>,
8571 and <literal>12.300</literal> specify the
8572 same number of milliseconds. To get three milliseconds, one must write
8573 <literal>12.003</literal>, which the conversion treats as
8574 12 + 0.003 = 12.003 seconds.
8575 </para>
8577 <para>
8578 Here is a more
8579 complex example:
8580 <literal>to_timestamp('15:12:02.020.001230', 'HH24:MI:SS.MS.US')</literal>
8581 is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
8582 1230 microseconds = 2.021230 seconds.
8583 </para>
8584 </listitem>
8586 <listitem>
8587 <para>
8588 <function>to_char(..., 'ID')</function>'s day of the week numbering
8589 matches the <function>extract(isodow from ...)</function> function, but
8590 <function>to_char(..., 'D')</function>'s does not match
8591 <function>extract(dow from ...)</function>'s day numbering.
8592 </para>
8593 </listitem>
8595 <listitem>
8596 <para>
8597 <function>to_char(interval)</function> formats <literal>HH</literal> and
8598 <literal>HH12</literal> as shown on a 12-hour clock, for example zero hours
8599 and 36 hours both output as <literal>12</literal>, while <literal>HH24</literal>
8600 outputs the full hour value, which can exceed 23 in
8601 an <type>interval</type> value.
8602 </para>
8603 </listitem>
8605 </itemizedlist>
8606 </para>
8608 <para>
8609 <xref linkend="functions-formatting-numeric-table"/> shows the
8610 template patterns available for formatting numeric values.
8611 </para>
8613 <table id="functions-formatting-numeric-table">
8614 <title>Template Patterns for Numeric Formatting</title>
8615 <tgroup cols="2">
8616 <thead>
8617 <row>
8618 <entry>Pattern</entry>
8619 <entry>Description</entry>
8620 </row>
8621 </thead>
8622 <tbody>
8623 <row>
8624 <entry><literal>9</literal></entry>
8625 <entry>digit position (can be dropped if insignificant)</entry>
8626 </row>
8627 <row>
8628 <entry><literal>0</literal></entry>
8629 <entry>digit position (will not be dropped, even if insignificant)</entry>
8630 </row>
8631 <row>
8632 <entry><literal>.</literal> (period)</entry>
8633 <entry>decimal point</entry>
8634 </row>
8635 <row>
8636 <entry><literal>,</literal> (comma)</entry>
8637 <entry>group (thousands) separator</entry>
8638 </row>
8639 <row>
8640 <entry><literal>PR</literal></entry>
8641 <entry>negative value in angle brackets</entry>
8642 </row>
8643 <row>
8644 <entry><literal>S</literal></entry>
8645 <entry>sign anchored to number (uses locale)</entry>
8646 </row>
8647 <row>
8648 <entry><literal>L</literal></entry>
8649 <entry>currency symbol (uses locale)</entry>
8650 </row>
8651 <row>
8652 <entry><literal>D</literal></entry>
8653 <entry>decimal point (uses locale)</entry>
8654 </row>
8655 <row>
8656 <entry><literal>G</literal></entry>
8657 <entry>group separator (uses locale)</entry>
8658 </row>
8659 <row>
8660 <entry><literal>MI</literal></entry>
8661 <entry>minus sign in specified position (if number &lt; 0)</entry>
8662 </row>
8663 <row>
8664 <entry><literal>PL</literal></entry>
8665 <entry>plus sign in specified position (if number &gt; 0)</entry>
8666 </row>
8667 <row>
8668 <entry><literal>SG</literal></entry>
8669 <entry>plus/minus sign in specified position</entry>
8670 </row>
8671 <row>
8672 <entry><literal>RN</literal></entry>
8673 <entry>Roman numeral (input between 1 and 3999)</entry>
8674 </row>
8675 <row>
8676 <entry><literal>TH</literal> or <literal>th</literal></entry>
8677 <entry>ordinal number suffix</entry>
8678 </row>
8679 <row>
8680 <entry><literal>V</literal></entry>
8681 <entry>shift specified number of digits (see notes)</entry>
8682 </row>
8683 <row>
8684 <entry><literal>EEEE</literal></entry>
8685 <entry>exponent for scientific notation</entry>
8686 </row>
8687 </tbody>
8688 </tgroup>
8689 </table>
8691 <para>
8692 Usage notes for numeric formatting:
8694 <itemizedlist>
8695 <listitem>
8696 <para>
8697 <literal>0</literal> specifies a digit position that will always be printed,
8698 even if it contains a leading/trailing zero. <literal>9</literal> also
8699 specifies a digit position, but if it is a leading zero then it will
8700 be replaced by a space, while if it is a trailing zero and fill mode
8701 is specified then it will be deleted. (For <function>to_number()</function>,
8702 these two pattern characters are equivalent.)
8703 </para>
8704 </listitem>
8706 <listitem>
8707 <para>
8708 If the format provides fewer fractional digits than the number being
8709 formatted, <function>to_char()</function> will round the number to
8710 the specified number of fractional digits.
8711 </para>
8712 </listitem>
8714 <listitem>
8715 <para>
8716 The pattern characters <literal>S</literal>, <literal>L</literal>, <literal>D</literal>,
8717 and <literal>G</literal> represent the sign, currency symbol, decimal point,
8718 and thousands separator characters defined by the current locale
8719 (see <xref linkend="guc-lc-monetary"/>
8720 and <xref linkend="guc-lc-numeric"/>). The pattern characters period
8721 and comma represent those exact characters, with the meanings of
8722 decimal point and thousands separator, regardless of locale.
8723 </para>
8724 </listitem>
8726 <listitem>
8727 <para>
8728 If no explicit provision is made for a sign
8729 in <function>to_char()</function>'s pattern, one column will be reserved for
8730 the sign, and it will be anchored to (appear just left of) the
8731 number. If <literal>S</literal> appears just left of some <literal>9</literal>'s,
8732 it will likewise be anchored to the number.
8733 </para>
8734 </listitem>
8736 <listitem>
8737 <para>
8738 A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
8739 <literal>MI</literal> is not anchored to
8740 the number; for example,
8741 <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
8742 but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
8743 (The Oracle implementation does not allow the use of
8744 <literal>MI</literal> before <literal>9</literal>, but rather
8745 requires that <literal>9</literal> precede
8746 <literal>MI</literal>.)
8747 </para>
8748 </listitem>
8750 <listitem>
8751 <para>
8752 <literal>TH</literal> does not convert values less than zero
8753 and does not convert fractional numbers.
8754 </para>
8755 </listitem>
8757 <listitem>
8758 <para>
8759 <literal>PL</literal>, <literal>SG</literal>, and
8760 <literal>TH</literal> are <productname>PostgreSQL</productname>
8761 extensions.
8762 </para>
8763 </listitem>
8765 <listitem>
8766 <para>
8767 In <function>to_number</function>, if non-data template patterns such
8768 as <literal>L</literal> or <literal>TH</literal> are used, the
8769 corresponding number of input characters are skipped, whether or not
8770 they match the template pattern, unless they are data characters
8771 (that is, digits, sign, decimal point, or comma). For
8772 example, <literal>TH</literal> would skip two non-data characters.
8773 </para>
8774 </listitem>
8776 <listitem>
8777 <para>
8778 <literal>V</literal> with <function>to_char</function>
8779 multiplies the input values by
8780 <literal>10^<replaceable>n</replaceable></literal>, where
8781 <replaceable>n</replaceable> is the number of digits following
8782 <literal>V</literal>. <literal>V</literal> with
8783 <function>to_number</function> divides in a similar manner.
8784 The <literal>V</literal> can be thought of as marking the position
8785 of an implicit decimal point in the input or output string.
8786 <function>to_char</function> and <function>to_number</function>
8787 do not support the use of
8788 <literal>V</literal> combined with a decimal point
8789 (e.g., <literal>99.9V99</literal> is not allowed).
8790 </para>
8791 </listitem>
8793 <listitem>
8794 <para>
8795 <literal>EEEE</literal> (scientific notation) cannot be used in
8796 combination with any of the other formatting patterns or
8797 modifiers other than digit and decimal point patterns, and must be at the end of the format string
8798 (e.g., <literal>9.99EEEE</literal> is a valid pattern).
8799 </para>
8800 </listitem>
8801 </itemizedlist>
8802 </para>
8804 <para>
8805 Certain modifiers can be applied to any template pattern to alter its
8806 behavior. For example, <literal>FM99.99</literal>
8807 is the <literal>99.99</literal> pattern with the
8808 <literal>FM</literal> modifier.
8809 <xref linkend="functions-formatting-numericmod-table"/> shows the
8810 modifier patterns for numeric formatting.
8811 </para>
8813 <table id="functions-formatting-numericmod-table">
8814 <title>Template Pattern Modifiers for Numeric Formatting</title>
8815 <tgroup cols="3">
8816 <thead>
8817 <row>
8818 <entry>Modifier</entry>
8819 <entry>Description</entry>
8820 <entry>Example</entry>
8821 </row>
8822 </thead>
8823 <tbody>
8824 <row>
8825 <entry><literal>FM</literal> prefix</entry>
8826 <entry>fill mode (suppress trailing zeroes and padding blanks)</entry>
8827 <entry><literal>FM99.99</literal></entry>
8828 </row>
8829 <row>
8830 <entry><literal>TH</literal> suffix</entry>
8831 <entry>upper case ordinal number suffix</entry>
8832 <entry><literal>999TH</literal></entry>
8833 </row>
8834 <row>
8835 <entry><literal>th</literal> suffix</entry>
8836 <entry>lower case ordinal number suffix</entry>
8837 <entry><literal>999th</literal></entry>
8838 </row>
8839 </tbody>
8840 </tgroup>
8841 </table>
8843 <para>
8844 <xref linkend="functions-formatting-examples-table"/> shows some
8845 examples of the use of the <function>to_char</function> function.
8846 </para>
8848 <table id="functions-formatting-examples-table">
8849 <title><function>to_char</function> Examples</title>
8850 <tgroup cols="2">
8851 <thead>
8852 <row>
8853 <entry>Expression</entry>
8854 <entry>Result</entry>
8855 </row>
8856 </thead>
8857 <tbody>
8858 <row>
8859 <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8860 <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
8861 </row>
8862 <row>
8863 <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8864 <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
8865 </row>
8866 <row>
8867 <entry><literal>to_char(current_timestamp AT TIME ZONE
8868 'UTC', 'YYYY-MM-DD"T"HH24:MI:SS"Z"')</literal></entry>
8869 <entry><literal>'2022-12-06T05:39:18Z'</literal>,
8870 <acronym>ISO</acronym> 8601 extended format</entry>
8871 </row>
8872 <row>
8873 <entry><literal>to_char(-0.1, '99.99')</literal></entry>
8874 <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
8875 </row>
8876 <row>
8877 <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
8878 <entry><literal>'-.1'</literal></entry>
8879 </row>
8880 <row>
8881 <entry><literal>to_char(-0.1, 'FM90.99')</literal></entry>
8882 <entry><literal>'-0.1'</literal></entry>
8883 </row>
8884 <row>
8885 <entry><literal>to_char(0.1, '0.9')</literal></entry>
8886 <entry><literal>'&nbsp;0.1'</literal></entry>
8887 </row>
8888 <row>
8889 <entry><literal>to_char(12, '9990999.9')</literal></entry>
8890 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
8891 </row>
8892 <row>
8893 <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
8894 <entry><literal>'0012.'</literal></entry>
8895 </row>
8896 <row>
8897 <entry><literal>to_char(485, '999')</literal></entry>
8898 <entry><literal>'&nbsp;485'</literal></entry>
8899 </row>
8900 <row>
8901 <entry><literal>to_char(-485, '999')</literal></entry>
8902 <entry><literal>'-485'</literal></entry>
8903 </row>
8904 <row>
8905 <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
8906 <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
8907 </row>
8908 <row>
8909 <entry><literal>to_char(1485, '9,999')</literal></entry>
8910 <entry><literal>'&nbsp;1,485'</literal></entry>
8911 </row>
8912 <row>
8913 <entry><literal>to_char(1485, '9G999')</literal></entry>
8914 <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
8915 </row>
8916 <row>
8917 <entry><literal>to_char(148.5, '999.999')</literal></entry>
8918 <entry><literal>'&nbsp;148.500'</literal></entry>
8919 </row>
8920 <row>
8921 <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
8922 <entry><literal>'148.5'</literal></entry>
8923 </row>
8924 <row>
8925 <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
8926 <entry><literal>'148.500'</literal></entry>
8927 </row>
8928 <row>
8929 <entry><literal>to_char(148.5, '999D999')</literal></entry>
8930 <entry><literal>'&nbsp;148,500'</literal></entry>
8931 </row>
8932 <row>
8933 <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
8934 <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
8935 </row>
8936 <row>
8937 <entry><literal>to_char(-485, '999S')</literal></entry>
8938 <entry><literal>'485-'</literal></entry>
8939 </row>
8940 <row>
8941 <entry><literal>to_char(-485, '999MI')</literal></entry>
8942 <entry><literal>'485-'</literal></entry>
8943 </row>
8944 <row>
8945 <entry><literal>to_char(485, '999MI')</literal></entry>
8946 <entry><literal>'485&nbsp;'</literal></entry>
8947 </row>
8948 <row>
8949 <entry><literal>to_char(485, 'FM999MI')</literal></entry>
8950 <entry><literal>'485'</literal></entry>
8951 </row>
8952 <row>
8953 <entry><literal>to_char(485, 'PL999')</literal></entry>
8954 <entry><literal>'+485'</literal></entry>
8955 </row>
8956 <row>
8957 <entry><literal>to_char(485, 'SG999')</literal></entry>
8958 <entry><literal>'+485'</literal></entry>
8959 </row>
8960 <row>
8961 <entry><literal>to_char(-485, 'SG999')</literal></entry>
8962 <entry><literal>'-485'</literal></entry>
8963 </row>
8964 <row>
8965 <entry><literal>to_char(-485, '9SG99')</literal></entry>
8966 <entry><literal>'4-85'</literal></entry>
8967 </row>
8968 <row>
8969 <entry><literal>to_char(-485, '999PR')</literal></entry>
8970 <entry><literal>'&lt;485&gt;'</literal></entry>
8971 </row>
8972 <row>
8973 <entry><literal>to_char(485, 'L999')</literal></entry>
8974 <entry><literal>'DM&nbsp;485'</literal></entry>
8975 </row>
8976 <row>
8977 <entry><literal>to_char(485, 'RN')</literal></entry>
8978 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
8979 </row>
8980 <row>
8981 <entry><literal>to_char(485, 'FMRN')</literal></entry>
8982 <entry><literal>'CDLXXXV'</literal></entry>
8983 </row>
8984 <row>
8985 <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
8986 <entry><literal>'V'</literal></entry>
8987 </row>
8988 <row>
8989 <entry><literal>to_char(482, '999th')</literal></entry>
8990 <entry><literal>'&nbsp;482nd'</literal></entry>
8991 </row>
8992 <row>
8993 <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
8994 <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
8995 </row>
8996 <row>
8997 <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
8998 <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
8999 </row>
9000 <row>
9001 <entry><literal>to_char(12, '99V999')</literal></entry>
9002 <entry><literal>'&nbsp;12000'</literal></entry>
9003 </row>
9004 <row>
9005 <entry><literal>to_char(12.4, '99V999')</literal></entry>
9006 <entry><literal>'&nbsp;12400'</literal></entry>
9007 </row>
9008 <row>
9009 <entry><literal>to_char(12.45, '99V9')</literal></entry>
9010 <entry><literal>'&nbsp;125'</literal></entry>
9011 </row>
9012 <row>
9013 <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
9014 <entry><literal>' 4.86e-04'</literal></entry>
9015 </row>
9016 </tbody>
9017 </tgroup>
9018 </table>
9020 </sect1>
9023 <sect1 id="functions-datetime">
9024 <title>Date/Time Functions and Operators</title>
9026 <para>
9027 <xref linkend="functions-datetime-table"/> shows the available
9028 functions for date/time value processing, with details appearing in
9029 the following subsections. <xref
9030 linkend="operators-datetime-table"/> illustrates the behaviors of
9031 the basic arithmetic operators (<literal>+</literal>,
9032 <literal>*</literal>, etc.). For formatting functions, refer to
9033 <xref linkend="functions-formatting"/>. You should be familiar with
9034 the background information on date/time data types from <xref
9035 linkend="datatype-datetime"/>.
9036 </para>
9038 <para>
9039 In addition, the usual comparison operators shown in
9040 <xref linkend="functions-comparison-op-table"/> are available for the
9041 date/time types. Dates and timestamps (with or without time zone) are
9042 all comparable, while times (with or without time zone) and intervals
9043 can only be compared to other values of the same data type. When
9044 comparing a timestamp without time zone to a timestamp with time zone,
9045 the former value is assumed to be given in the time zone specified by
9046 the <xref linkend="guc-timezone"/> configuration parameter, and is
9047 rotated to UTC for comparison to the latter value (which is already
9048 in UTC internally). Similarly, a date value is assumed to represent
9049 midnight in the <varname>TimeZone</varname> zone when comparing it
9050 to a timestamp.
9051 </para>
9053 <para>
9054 All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
9055 inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
9056 with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
9057 For brevity, these variants are not shown separately. Also, the
9058 <literal>+</literal> and <literal>*</literal> operators come in commutative pairs (for
9059 example both <type>date</type> <literal>+</literal> <type>integer</type>
9060 and <type>integer</type> <literal>+</literal> <type>date</type>); we show
9061 only one of each such pair.
9062 </para>
9064 <table id="operators-datetime-table">
9065 <title>Date/Time Operators</title>
9067 <tgroup cols="1">
9068 <thead>
9069 <row>
9070 <entry role="func_table_entry"><para role="func_signature">
9071 Operator
9072 </para>
9073 <para>
9074 Description
9075 </para>
9076 <para>
9077 Example(s)
9078 </para></entry>
9079 </row>
9080 </thead>
9082 <tbody>
9083 <row>
9084 <entry role="func_table_entry"><para role="func_signature">
9085 <type>date</type> <literal>+</literal> <type>integer</type>
9086 <returnvalue>date</returnvalue>
9087 </para>
9088 <para>
9089 Add a number of days to a date
9090 </para>
9091 <para>
9092 <literal>date '2001-09-28' + 7</literal>
9093 <returnvalue>2001-10-05</returnvalue>
9094 </para></entry>
9095 </row>
9097 <row>
9098 <entry role="func_table_entry"><para role="func_signature">
9099 <type>date</type> <literal>+</literal> <type>interval</type>
9100 <returnvalue>timestamp</returnvalue>
9101 </para>
9102 <para>
9103 Add an interval to a date
9104 </para>
9105 <para>
9106 <literal>date '2001-09-28' + interval '1 hour'</literal>
9107 <returnvalue>2001-09-28 01:00:00</returnvalue>
9108 </para></entry>
9109 </row>
9111 <row>
9112 <entry role="func_table_entry"><para role="func_signature">
9113 <type>date</type> <literal>+</literal> <type>time</type>
9114 <returnvalue>timestamp</returnvalue>
9115 </para>
9116 <para>
9117 Add a time-of-day to a date
9118 </para>
9119 <para>
9120 <literal>date '2001-09-28' + time '03:00'</literal>
9121 <returnvalue>2001-09-28 03:00:00</returnvalue>
9122 </para></entry>
9123 </row>
9125 <row>
9126 <entry role="func_table_entry"><para role="func_signature">
9127 <type>interval</type> <literal>+</literal> <type>interval</type>
9128 <returnvalue>interval</returnvalue>
9129 </para>
9130 <para>
9131 Add intervals
9132 </para>
9133 <para>
9134 <literal>interval '1 day' + interval '1 hour'</literal>
9135 <returnvalue>1 day 01:00:00</returnvalue>
9136 </para></entry>
9137 </row>
9139 <row>
9140 <entry role="func_table_entry"><para role="func_signature">
9141 <type>timestamp</type> <literal>+</literal> <type>interval</type>
9142 <returnvalue>timestamp</returnvalue>
9143 </para>
9144 <para>
9145 Add an interval to a timestamp
9146 </para>
9147 <para>
9148 <literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal>
9149 <returnvalue>2001-09-29 00:00:00</returnvalue>
9150 </para></entry>
9151 </row>
9153 <row>
9154 <entry role="func_table_entry"><para role="func_signature">
9155 <type>time</type> <literal>+</literal> <type>interval</type>
9156 <returnvalue>time</returnvalue>
9157 </para>
9158 <para>
9159 Add an interval to a time
9160 </para>
9161 <para>
9162 <literal>time '01:00' + interval '3 hours'</literal>
9163 <returnvalue>04:00:00</returnvalue>
9164 </para></entry>
9165 </row>
9167 <row>
9168 <entry role="func_table_entry"><para role="func_signature">
9169 <literal>-</literal> <type>interval</type>
9170 <returnvalue>interval</returnvalue>
9171 </para>
9172 <para>
9173 Negate an interval
9174 </para>
9175 <para>
9176 <literal>- interval '23 hours'</literal>
9177 <returnvalue>-23:00:00</returnvalue>
9178 </para></entry>
9179 </row>
9181 <row>
9182 <entry role="func_table_entry"><para role="func_signature">
9183 <type>date</type> <literal>-</literal> <type>date</type>
9184 <returnvalue>integer</returnvalue>
9185 </para>
9186 <para>
9187 Subtract dates, producing the number of days elapsed
9188 </para>
9189 <para>
9190 <literal>date '2001-10-01' - date '2001-09-28'</literal>
9191 <returnvalue>3</returnvalue>
9192 </para></entry>
9193 </row>
9195 <row>
9196 <entry role="func_table_entry"><para role="func_signature">
9197 <type>date</type> <literal>-</literal> <type>integer</type>
9198 <returnvalue>date</returnvalue>
9199 </para>
9200 <para>
9201 Subtract a number of days from a date
9202 </para>
9203 <para>
9204 <literal>date '2001-10-01' - 7</literal>
9205 <returnvalue>2001-09-24</returnvalue>
9206 </para></entry>
9207 </row>
9209 <row>
9210 <entry role="func_table_entry"><para role="func_signature">
9211 <type>date</type> <literal>-</literal> <type>interval</type>
9212 <returnvalue>timestamp</returnvalue>
9213 </para>
9214 <para>
9215 Subtract an interval from a date
9216 </para>
9217 <para>
9218 <literal>date '2001-09-28' - interval '1 hour'</literal>
9219 <returnvalue>2001-09-27 23:00:00</returnvalue>
9220 </para></entry>
9221 </row>
9223 <row>
9224 <entry role="func_table_entry"><para role="func_signature">
9225 <type>time</type> <literal>-</literal> <type>time</type>
9226 <returnvalue>interval</returnvalue>
9227 </para>
9228 <para>
9229 Subtract times
9230 </para>
9231 <para>
9232 <literal>time '05:00' - time '03:00'</literal>
9233 <returnvalue>02:00:00</returnvalue>
9234 </para></entry>
9235 </row>
9237 <row>
9238 <entry role="func_table_entry"><para role="func_signature">
9239 <type>time</type> <literal>-</literal> <type>interval</type>
9240 <returnvalue>time</returnvalue>
9241 </para>
9242 <para>
9243 Subtract an interval from a time
9244 </para>
9245 <para>
9246 <literal>time '05:00' - interval '2 hours'</literal>
9247 <returnvalue>03:00:00</returnvalue>
9248 </para></entry>
9249 </row>
9251 <row>
9252 <entry role="func_table_entry"><para role="func_signature">
9253 <type>timestamp</type> <literal>-</literal> <type>interval</type>
9254 <returnvalue>timestamp</returnvalue>
9255 </para>
9256 <para>
9257 Subtract an interval from a timestamp
9258 </para>
9259 <para>
9260 <literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal>
9261 <returnvalue>2001-09-28 00:00:00</returnvalue>
9262 </para></entry>
9263 </row>
9265 <row>
9266 <entry role="func_table_entry"><para role="func_signature">
9267 <type>interval</type> <literal>-</literal> <type>interval</type>
9268 <returnvalue>interval</returnvalue>
9269 </para>
9270 <para>
9271 Subtract intervals
9272 </para>
9273 <para>
9274 <literal>interval '1 day' - interval '1 hour'</literal>
9275 <returnvalue>1 day -01:00:00</returnvalue>
9276 </para></entry>
9277 </row>
9279 <row>
9280 <entry role="func_table_entry"><para role="func_signature">
9281 <type>timestamp</type> <literal>-</literal> <type>timestamp</type>
9282 <returnvalue>interval</returnvalue>
9283 </para>
9284 <para>
9285 Subtract timestamps (converting 24-hour intervals into days,
9286 similarly to <link
9287 linkend="function-justify-hours"><function>justify_hours()</function></link>)
9288 </para>
9289 <para>
9290 <literal>timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00'</literal>
9291 <returnvalue>63 days 15:00:00</returnvalue>
9292 </para></entry>
9293 </row>
9295 <row>
9296 <entry role="func_table_entry"><para role="func_signature">
9297 <type>interval</type> <literal>*</literal> <type>double precision</type>
9298 <returnvalue>interval</returnvalue>
9299 </para>
9300 <para>
9301 Multiply an interval by a scalar
9302 </para>
9303 <para>
9304 <literal>interval '1 second' * 900</literal>
9305 <returnvalue>00:15:00</returnvalue>
9306 </para>
9307 <para>
9308 <literal>interval '1 day' * 21</literal>
9309 <returnvalue>21 days</returnvalue>
9310 </para>
9311 <para>
9312 <literal>interval '1 hour' * 3.5</literal>
9313 <returnvalue>03:30:00</returnvalue>
9314 </para></entry>
9315 </row>
9317 <row>
9318 <entry role="func_table_entry"><para role="func_signature">
9319 <type>interval</type> <literal>/</literal> <type>double precision</type>
9320 <returnvalue>interval</returnvalue>
9321 </para>
9322 <para>
9323 Divide an interval by a scalar
9324 </para>
9325 <para>
9326 <literal>interval '1 hour' / 1.5</literal>
9327 <returnvalue>00:40:00</returnvalue>
9328 </para></entry>
9329 </row>
9330 </tbody>
9331 </tgroup>
9332 </table>
9334 <table id="functions-datetime-table">
9335 <title>Date/Time Functions</title>
9336 <tgroup cols="1">
9337 <thead>
9338 <row>
9339 <entry role="func_table_entry"><para role="func_signature">
9340 Function
9341 </para>
9342 <para>
9343 Description
9344 </para>
9345 <para>
9346 Example(s)
9347 </para></entry>
9348 </row>
9349 </thead>
9351 <tbody>
9352 <row>
9353 <entry role="func_table_entry"><para role="func_signature">
9354 <indexterm>
9355 <primary>age</primary>
9356 </indexterm>
9357 <function>age</function> ( <type>timestamp</type>, <type>timestamp</type> )
9358 <returnvalue>interval</returnvalue>
9359 </para>
9360 <para>
9361 Subtract arguments, producing a <quote>symbolic</quote> result that
9362 uses years and months, rather than just days
9363 </para>
9364 <para>
9365 <literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal>
9366 <returnvalue>43 years 9 mons 27 days</returnvalue>
9367 </para></entry>
9368 </row>
9370 <row>
9371 <entry role="func_table_entry"><para role="func_signature">
9372 <function>age</function> ( <type>timestamp</type> )
9373 <returnvalue>interval</returnvalue>
9374 </para>
9375 <para>
9376 Subtract argument from <function>current_date</function> (at midnight)
9377 </para>
9378 <para>
9379 <literal>age(timestamp '1957-06-13')</literal>
9380 <returnvalue>62 years 6 mons 10 days</returnvalue>
9381 </para></entry>
9382 </row>
9384 <row>
9385 <entry role="func_table_entry"><para role="func_signature">
9386 <indexterm>
9387 <primary>clock_timestamp</primary>
9388 </indexterm>
9389 <function>clock_timestamp</function> ( )
9390 <returnvalue>timestamp with time zone</returnvalue>
9391 </para>
9392 <para>
9393 Current date and time (changes during statement execution);
9394 see <xref linkend="functions-datetime-current"/>
9395 </para>
9396 <para>
9397 <literal>clock_timestamp()</literal>
9398 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9399 </para></entry>
9400 </row>
9402 <row>
9403 <entry role="func_table_entry"><para role="func_signature">
9404 <indexterm>
9405 <primary>current_date</primary>
9406 </indexterm>
9407 <function>current_date</function>
9408 <returnvalue>date</returnvalue>
9409 </para>
9410 <para>
9411 Current date; see <xref linkend="functions-datetime-current"/>
9412 </para>
9413 <para>
9414 <literal>current_date</literal>
9415 <returnvalue>2019-12-23</returnvalue>
9416 </para></entry>
9417 </row>
9419 <row>
9420 <entry role="func_table_entry"><para role="func_signature">
9421 <indexterm>
9422 <primary>current_time</primary>
9423 </indexterm>
9424 <function>current_time</function>
9425 <returnvalue>time with time zone</returnvalue>
9426 </para>
9427 <para>
9428 Current time of day; see <xref linkend="functions-datetime-current"/>
9429 </para>
9430 <para>
9431 <literal>current_time</literal>
9432 <returnvalue>14:39:53.662522-05</returnvalue>
9433 </para></entry>
9434 </row>
9436 <row>
9437 <entry role="func_table_entry"><para role="func_signature">
9438 <function>current_time</function> ( <type>integer</type> )
9439 <returnvalue>time with time zone</returnvalue>
9440 </para>
9441 <para>
9442 Current time of day, with limited precision;
9443 see <xref linkend="functions-datetime-current"/>
9444 </para>
9445 <para>
9446 <literal>current_time(2)</literal>
9447 <returnvalue>14:39:53.66-05</returnvalue>
9448 </para></entry>
9449 </row>
9451 <row>
9452 <entry role="func_table_entry"><para role="func_signature">
9453 <indexterm>
9454 <primary>current_timestamp</primary>
9455 </indexterm>
9456 <function>current_timestamp</function>
9457 <returnvalue>timestamp with time zone</returnvalue>
9458 </para>
9459 <para>
9460 Current date and time (start of current transaction);
9461 see <xref linkend="functions-datetime-current"/>
9462 </para>
9463 <para>
9464 <literal>current_timestamp</literal>
9465 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9466 </para></entry>
9467 </row>
9469 <row>
9470 <entry role="func_table_entry"><para role="func_signature">
9471 <function>current_timestamp</function> ( <type>integer</type> )
9472 <returnvalue>timestamp with time zone</returnvalue>
9473 </para>
9474 <para>
9475 Current date and time (start of current transaction), with limited precision;
9476 see <xref linkend="functions-datetime-current"/>
9477 </para>
9478 <para>
9479 <literal>current_timestamp(0)</literal>
9480 <returnvalue>2019-12-23 14:39:53-05</returnvalue>
9481 </para></entry>
9482 </row>
9484 <row>
9485 <entry role="func_table_entry"><para role="func_signature">
9486 <indexterm>
9487 <primary>date_add</primary>
9488 </indexterm>
9489 <function>date_add</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
9490 <returnvalue>timestamp with time zone</returnvalue>
9491 </para>
9492 <para>
9493 Add an <type>interval</type> to a <type>timestamp with time
9494 zone</type>, computing times of day and daylight-savings adjustments
9495 according to the time zone named by the third argument, or the
9496 current <xref linkend="guc-timezone"/> setting if that is omitted.
9497 The form with two arguments is equivalent to the <type>timestamp with
9498 time zone</type> <literal>+</literal> <type>interval</type> operator.
9499 </para>
9500 <para>
9501 <literal>date_add('2021-10-31 00:00:00+02'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
9502 <returnvalue>2021-10-31 23:00:00+00</returnvalue>
9503 </para></entry>
9504 </row>
9506 <row>
9507 <entry role="func_table_entry"><para role="func_signature">
9508 <function>date_bin</function> ( <type>interval</type>, <type>timestamp</type>, <type>timestamp</type> )
9509 <returnvalue>timestamp</returnvalue>
9510 </para>
9511 <para>
9512 Bin input into specified interval aligned with specified origin; see <xref linkend="functions-datetime-bin"/>
9513 </para>
9514 <para>
9515 <literal>date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00')</literal>
9516 <returnvalue>2001-02-16 20:35:00</returnvalue>
9517 </para></entry>
9518 </row>
9520 <row>
9521 <entry role="func_table_entry"><para role="func_signature">
9522 <indexterm>
9523 <primary>date_part</primary>
9524 </indexterm>
9525 <function>date_part</function> ( <type>text</type>, <type>timestamp</type> )
9526 <returnvalue>double precision</returnvalue>
9527 </para>
9528 <para>
9529 Get timestamp subfield (equivalent to <function>extract</function>);
9530 see <xref linkend="functions-datetime-extract"/>
9531 </para>
9532 <para>
9533 <literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal>
9534 <returnvalue>20</returnvalue>
9535 </para></entry>
9536 </row>
9538 <row>
9539 <entry role="func_table_entry"><para role="func_signature">
9540 <function>date_part</function> ( <type>text</type>, <type>interval</type> )
9541 <returnvalue>double precision</returnvalue>
9542 </para>
9543 <para>
9544 Get interval subfield (equivalent to <function>extract</function>);
9545 see <xref linkend="functions-datetime-extract"/>
9546 </para>
9547 <para>
9548 <literal>date_part('month', interval '2 years 3 months')</literal>
9549 <returnvalue>3</returnvalue>
9550 </para></entry>
9551 </row>
9553 <row>
9554 <entry role="func_table_entry"><para role="func_signature">
9555 <indexterm>
9556 <primary>date_subtract</primary>
9557 </indexterm>
9558 <function>date_subtract</function> ( <type>timestamp with time zone</type>, <type>interval</type> <optional>, <type>text</type> </optional> )
9559 <returnvalue>timestamp with time zone</returnvalue>
9560 </para>
9561 <para>
9562 Subtract an <type>interval</type> from a <type>timestamp with time
9563 zone</type>, computing times of day and daylight-savings adjustments
9564 according to the time zone named by the third argument, or the
9565 current <xref linkend="guc-timezone"/> setting if that is omitted.
9566 The form with two arguments is equivalent to the <type>timestamp with
9567 time zone</type> <literal>-</literal> <type>interval</type> operator.
9568 </para>
9569 <para>
9570 <literal>date_subtract('2021-11-01 00:00:00+01'::timestamptz, '1 day'::interval, 'Europe/Warsaw')</literal>
9571 <returnvalue>2021-10-30 22:00:00+00</returnvalue>
9572 </para></entry>
9573 </row>
9575 <row>
9576 <entry role="func_table_entry"><para role="func_signature">
9577 <indexterm>
9578 <primary>date_trunc</primary>
9579 </indexterm>
9580 <function>date_trunc</function> ( <type>text</type>, <type>timestamp</type> )
9581 <returnvalue>timestamp</returnvalue>
9582 </para>
9583 <para>
9584 Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
9585 </para>
9586 <para>
9587 <literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal>
9588 <returnvalue>2001-02-16 20:00:00</returnvalue>
9589 </para></entry>
9590 </row>
9592 <row>
9593 <entry role="func_table_entry"><para role="func_signature">
9594 <function>date_trunc</function> ( <type>text</type>, <type>timestamp with time zone</type>, <type>text</type> )
9595 <returnvalue>timestamp with time zone</returnvalue>
9596 </para>
9597 <para>
9598 Truncate to specified precision in the specified time zone; see
9599 <xref linkend="functions-datetime-trunc"/>
9600 </para>
9601 <para>
9602 <literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal>
9603 <returnvalue>2001-02-16 13:00:00+00</returnvalue>
9604 </para></entry>
9605 </row>
9607 <row>
9608 <entry role="func_table_entry"><para role="func_signature">
9609 <function>date_trunc</function> ( <type>text</type>, <type>interval</type> )
9610 <returnvalue>interval</returnvalue>
9611 </para>
9612 <para>
9613 Truncate to specified precision; see
9614 <xref linkend="functions-datetime-trunc"/>
9615 </para>
9616 <para>
9617 <literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal>
9618 <returnvalue>2 days 03:00:00</returnvalue>
9619 </para></entry>
9620 </row>
9622 <row>
9623 <entry role="func_table_entry"><para role="func_signature">
9624 <indexterm>
9625 <primary>extract</primary>
9626 </indexterm>
9627 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> )
9628 <returnvalue>numeric</returnvalue>
9629 </para>
9630 <para>
9631 Get timestamp subfield; see <xref linkend="functions-datetime-extract"/>
9632 </para>
9633 <para>
9634 <literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal>
9635 <returnvalue>20</returnvalue>
9636 </para></entry>
9637 </row>
9639 <row>
9640 <entry role="func_table_entry"><para role="func_signature">
9641 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> )
9642 <returnvalue>numeric</returnvalue>
9643 </para>
9644 <para>
9645 Get interval subfield; see <xref linkend="functions-datetime-extract"/>
9646 </para>
9647 <para>
9648 <literal>extract(month from interval '2 years 3 months')</literal>
9649 <returnvalue>3</returnvalue>
9650 </para></entry>
9651 </row>
9653 <row>
9654 <entry role="func_table_entry"><para role="func_signature">
9655 <indexterm>
9656 <primary>isfinite</primary>
9657 </indexterm>
9658 <function>isfinite</function> ( <type>date</type> )
9659 <returnvalue>boolean</returnvalue>
9660 </para>
9661 <para>
9662 Test for finite date (not +/-infinity)
9663 </para>
9664 <para>
9665 <literal>isfinite(date '2001-02-16')</literal>
9666 <returnvalue>true</returnvalue>
9667 </para></entry>
9668 </row>
9670 <row>
9671 <entry role="func_table_entry"><para role="func_signature">
9672 <function>isfinite</function> ( <type>timestamp</type> )
9673 <returnvalue>boolean</returnvalue>
9674 </para>
9675 <para>
9676 Test for finite timestamp (not +/-infinity)
9677 </para>
9678 <para>
9679 <literal>isfinite(timestamp 'infinity')</literal>
9680 <returnvalue>false</returnvalue>
9681 </para></entry>
9682 </row>
9684 <row>
9685 <entry role="func_table_entry"><para role="func_signature">
9686 <function>isfinite</function> ( <type>interval</type> )
9687 <returnvalue>boolean</returnvalue>
9688 </para>
9689 <para>
9690 Test for finite interval (not +/-infinity)
9691 </para>
9692 <para>
9693 <literal>isfinite(interval '4 hours')</literal>
9694 <returnvalue>true</returnvalue>
9695 </para></entry>
9696 </row>
9698 <row>
9699 <entry role="func_table_entry"><para role="func_signature">
9700 <indexterm id="function-justify-days">
9701 <primary>justify_days</primary>
9702 </indexterm>
9703 <function>justify_days</function> ( <type>interval</type> )
9704 <returnvalue>interval</returnvalue>
9705 </para>
9706 <para>
9707 Adjust interval, converting 30-day time periods to months
9708 </para>
9709 <para>
9710 <literal>justify_days(interval '1 year 65 days')</literal>
9711 <returnvalue>1 year 2 mons 5 days</returnvalue>
9712 </para></entry>
9713 </row>
9715 <row>
9716 <entry role="func_table_entry"><para role="func_signature">
9717 <indexterm id="function-justify-hours">
9718 <primary>justify_hours</primary>
9719 </indexterm>
9720 <function>justify_hours</function> ( <type>interval</type> )
9721 <returnvalue>interval</returnvalue>
9722 </para>
9723 <para>
9724 Adjust interval, converting 24-hour time periods to days
9725 </para>
9726 <para>
9727 <literal>justify_hours(interval '50 hours 10 minutes')</literal>
9728 <returnvalue>2 days 02:10:00</returnvalue>
9729 </para></entry>
9730 </row>
9732 <row>
9733 <entry role="func_table_entry"><para role="func_signature">
9734 <indexterm>
9735 <primary>justify_interval</primary>
9736 </indexterm>
9737 <function>justify_interval</function> ( <type>interval</type> )
9738 <returnvalue>interval</returnvalue>
9739 </para>
9740 <para>
9741 Adjust interval using <function>justify_days</function>
9742 and <function>justify_hours</function>, with additional sign
9743 adjustments
9744 </para>
9745 <para>
9746 <literal>justify_interval(interval '1 mon -1 hour')</literal>
9747 <returnvalue>29 days 23:00:00</returnvalue>
9748 </para></entry>
9749 </row>
9751 <row>
9752 <entry role="func_table_entry"><para role="func_signature">
9753 <indexterm>
9754 <primary>localtime</primary>
9755 </indexterm>
9756 <function>localtime</function>
9757 <returnvalue>time</returnvalue>
9758 </para>
9759 <para>
9760 Current time of day;
9761 see <xref linkend="functions-datetime-current"/>
9762 </para>
9763 <para>
9764 <literal>localtime</literal>
9765 <returnvalue>14:39:53.662522</returnvalue>
9766 </para></entry>
9767 </row>
9769 <row>
9770 <entry role="func_table_entry"><para role="func_signature">
9771 <function>localtime</function> ( <type>integer</type> )
9772 <returnvalue>time</returnvalue>
9773 </para>
9774 <para>
9775 Current time of day, with limited precision;
9776 see <xref linkend="functions-datetime-current"/>
9777 </para>
9778 <para>
9779 <literal>localtime(0)</literal>
9780 <returnvalue>14:39:53</returnvalue>
9781 </para></entry>
9782 </row>
9784 <row>
9785 <entry role="func_table_entry"><para role="func_signature">
9786 <indexterm>
9787 <primary>localtimestamp</primary>
9788 </indexterm>
9789 <function>localtimestamp</function>
9790 <returnvalue>timestamp</returnvalue>
9791 </para>
9792 <para>
9793 Current date and time (start of current transaction);
9794 see <xref linkend="functions-datetime-current"/>
9795 </para>
9796 <para>
9797 <literal>localtimestamp</literal>
9798 <returnvalue>2019-12-23 14:39:53.662522</returnvalue>
9799 </para></entry>
9800 </row>
9802 <row>
9803 <entry role="func_table_entry"><para role="func_signature">
9804 <function>localtimestamp</function> ( <type>integer</type> )
9805 <returnvalue>timestamp</returnvalue>
9806 </para>
9807 <para>
9808 Current date and time (start of current
9809 transaction), with limited precision;
9810 see <xref linkend="functions-datetime-current"/>
9811 </para>
9812 <para>
9813 <literal>localtimestamp(2)</literal>
9814 <returnvalue>2019-12-23 14:39:53.66</returnvalue>
9815 </para></entry>
9816 </row>
9818 <row>
9819 <entry role="func_table_entry"><para role="func_signature">
9820 <indexterm>
9821 <primary>make_date</primary>
9822 </indexterm>
9823 <function>make_date</function> ( <parameter>year</parameter> <type>int</type>,
9824 <parameter>month</parameter> <type>int</type>,
9825 <parameter>day</parameter> <type>int</type> )
9826 <returnvalue>date</returnvalue>
9827 </para>
9828 <para>
9829 Create date from year, month and day fields
9830 (negative years signify BC)
9831 </para>
9832 <para>
9833 <literal>make_date(2013, 7, 15)</literal>
9834 <returnvalue>2013-07-15</returnvalue>
9835 </para></entry>
9836 </row>
9838 <row>
9839 <entry role="func_table_entry"><para role="func_signature"><indexterm>
9840 <primary>make_interval</primary>
9841 </indexterm>
9842 <function>make_interval</function> ( <optional> <parameter>years</parameter> <type>int</type>
9843 <optional>, <parameter>months</parameter> <type>int</type>
9844 <optional>, <parameter>weeks</parameter> <type>int</type>
9845 <optional>, <parameter>days</parameter> <type>int</type>
9846 <optional>, <parameter>hours</parameter> <type>int</type>
9847 <optional>, <parameter>mins</parameter> <type>int</type>
9848 <optional>, <parameter>secs</parameter> <type>double precision</type>
9849 </optional></optional></optional></optional></optional></optional></optional> )
9850 <returnvalue>interval</returnvalue>
9851 </para>
9852 <para>
9853 Create interval from years, months, weeks, days, hours, minutes and
9854 seconds fields, each of which can default to zero
9855 </para>
9856 <para>
9857 <literal>make_interval(days =&gt; 10)</literal>
9858 <returnvalue>10 days</returnvalue>
9859 </para></entry>
9860 </row>
9862 <row>
9863 <entry role="func_table_entry"><para role="func_signature">
9864 <indexterm>
9865 <primary>make_time</primary>
9866 </indexterm>
9867 <function>make_time</function> ( <parameter>hour</parameter> <type>int</type>,
9868 <parameter>min</parameter> <type>int</type>,
9869 <parameter>sec</parameter> <type>double precision</type> )
9870 <returnvalue>time</returnvalue>
9871 </para>
9872 <para>
9873 Create time from hour, minute and seconds fields
9874 </para>
9875 <para>
9876 <literal>make_time(8, 15, 23.5)</literal>
9877 <returnvalue>08:15:23.5</returnvalue>
9878 </para></entry>
9879 </row>
9881 <row>
9882 <entry role="func_table_entry"><para role="func_signature">
9883 <indexterm>
9884 <primary>make_timestamp</primary>
9885 </indexterm>
9886 <function>make_timestamp</function> ( <parameter>year</parameter> <type>int</type>,
9887 <parameter>month</parameter> <type>int</type>,
9888 <parameter>day</parameter> <type>int</type>,
9889 <parameter>hour</parameter> <type>int</type>,
9890 <parameter>min</parameter> <type>int</type>,
9891 <parameter>sec</parameter> <type>double precision</type> )
9892 <returnvalue>timestamp</returnvalue>
9893 </para>
9894 <para>
9895 Create timestamp from year, month, day, hour, minute and seconds fields
9896 (negative years signify BC)
9897 </para>
9898 <para>
9899 <literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal>
9900 <returnvalue>2013-07-15 08:15:23.5</returnvalue>
9901 </para></entry>
9902 </row>
9904 <row>
9905 <entry role="func_table_entry"><para role="func_signature">
9906 <indexterm>
9907 <primary>make_timestamptz</primary>
9908 </indexterm>
9909 <function>make_timestamptz</function> ( <parameter>year</parameter> <type>int</type>,
9910 <parameter>month</parameter> <type>int</type>,
9911 <parameter>day</parameter> <type>int</type>,
9912 <parameter>hour</parameter> <type>int</type>,
9913 <parameter>min</parameter> <type>int</type>,
9914 <parameter>sec</parameter> <type>double precision</type>
9915 <optional>, <parameter>timezone</parameter> <type>text</type> </optional> )
9916 <returnvalue>timestamp with time zone</returnvalue>
9917 </para>
9918 <para>
9919 Create timestamp with time zone from year, month, day, hour, minute
9920 and seconds fields (negative years signify BC).
9921 If <parameter>timezone</parameter> is not
9922 specified, the current time zone is used; the examples assume the
9923 session time zone is <literal>Europe/London</literal>
9924 </para>
9925 <para>
9926 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal>
9927 <returnvalue>2013-07-15 08:15:23.5+01</returnvalue>
9928 </para>
9929 <para>
9930 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')</literal>
9931 <returnvalue>2013-07-15 13:15:23.5+01</returnvalue>
9932 </para></entry>
9933 </row>
9935 <row>
9936 <entry role="func_table_entry"><para role="func_signature">
9937 <indexterm>
9938 <primary>now</primary>
9939 </indexterm>
9940 <function>now</function> ( )
9941 <returnvalue>timestamp with time zone</returnvalue>
9942 </para>
9943 <para>
9944 Current date and time (start of current transaction);
9945 see <xref linkend="functions-datetime-current"/>
9946 </para>
9947 <para>
9948 <literal>now()</literal>
9949 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9950 </para></entry>
9951 </row>
9953 <row>
9954 <entry role="func_table_entry"><para role="func_signature">
9955 <indexterm>
9956 <primary>statement_timestamp</primary>
9957 </indexterm>
9958 <function>statement_timestamp</function> ( )
9959 <returnvalue>timestamp with time zone</returnvalue>
9960 </para>
9961 <para>
9962 Current date and time (start of current statement);
9963 see <xref linkend="functions-datetime-current"/>
9964 </para>
9965 <para>
9966 <literal>statement_timestamp()</literal>
9967 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9968 </para></entry>
9969 </row>
9971 <row>
9972 <entry role="func_table_entry"><para role="func_signature">
9973 <indexterm>
9974 <primary>timeofday</primary>
9975 </indexterm>
9976 <function>timeofday</function> ( )
9977 <returnvalue>text</returnvalue>
9978 </para>
9979 <para>
9980 Current date and time
9981 (like <function>clock_timestamp</function>, but as a <type>text</type> string);
9982 see <xref linkend="functions-datetime-current"/>
9983 </para>
9984 <para>
9985 <literal>timeofday()</literal>
9986 <returnvalue>Mon Dec 23 14:39:53.662522 2019 EST</returnvalue>
9987 </para></entry>
9988 </row>
9990 <row>
9991 <entry role="func_table_entry"><para role="func_signature">
9992 <indexterm>
9993 <primary>transaction_timestamp</primary>
9994 </indexterm>
9995 <function>transaction_timestamp</function> ( )
9996 <returnvalue>timestamp with time zone</returnvalue>
9997 </para>
9998 <para>
9999 Current date and time (start of current transaction);
10000 see <xref linkend="functions-datetime-current"/>
10001 </para>
10002 <para>
10003 <literal>transaction_timestamp()</literal>
10004 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
10005 </para></entry>
10006 </row>
10008 <row>
10009 <entry role="func_table_entry"><para role="func_signature">
10010 <indexterm>
10011 <primary>to_timestamp</primary>
10012 </indexterm>
10013 <function>to_timestamp</function> ( <type>double precision</type> )
10014 <returnvalue>timestamp with time zone</returnvalue>
10015 </para>
10016 <para>
10017 Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
10018 timestamp with time zone
10019 </para>
10020 <para>
10021 <literal>to_timestamp(1284352323)</literal>
10022 <returnvalue>2010-09-13 04:32:03+00</returnvalue>
10023 </para></entry>
10024 </row>
10025 </tbody>
10026 </tgroup>
10027 </table>
10029 <para>
10030 <indexterm>
10031 <primary>OVERLAPS</primary>
10032 </indexterm>
10033 In addition to these functions, the SQL <literal>OVERLAPS</literal> operator is
10034 supported:
10035 <synopsis>
10036 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
10037 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
10038 </synopsis>
10039 This expression yields true when two time periods (defined by their
10040 endpoints) overlap, false when they do not overlap. The endpoints
10041 can be specified as pairs of dates, times, or time stamps; or as
10042 a date, time, or time stamp followed by an interval. When a pair
10043 of values is provided, either the start or the end can be written
10044 first; <literal>OVERLAPS</literal> automatically takes the earlier value
10045 of the pair as the start. Each time period is considered to
10046 represent the half-open interval <replaceable>start</replaceable> <literal>&lt;=</literal>
10047 <replaceable>time</replaceable> <literal>&lt;</literal> <replaceable>end</replaceable>, unless
10048 <replaceable>start</replaceable> and <replaceable>end</replaceable> are equal in which case it
10049 represents that single time instant. This means for instance that two
10050 time periods with only an endpoint in common do not overlap.
10051 </para>
10053 <screen>
10054 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
10055 (DATE '2001-10-30', DATE '2002-10-30');
10056 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
10057 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
10058 (DATE '2001-10-30', DATE '2002-10-30');
10059 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
10060 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
10061 (DATE '2001-10-30', DATE '2001-10-31');
10062 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
10063 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
10064 (DATE '2001-10-30', DATE '2001-10-31');
10065 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
10066 </screen>
10068 <para>
10069 When adding an <type>interval</type> value to (or subtracting an
10070 <type>interval</type> value from) a <type>timestamp</type>
10071 or <type>timestamp with time zone</type> value, the months, days, and
10072 microseconds fields of the <type>interval</type> value are handled in turn.
10073 First, a nonzero months field advances or decrements the date of the
10074 timestamp by the indicated number of months, keeping the day of month the
10075 same unless it would be past the end of the new month, in which case the
10076 last day of that month is used. (For example, March 31 plus 1 month
10077 becomes April 30, but March 31 plus 2 months becomes May 31.)
10078 Then the days field advances or decrements the date of the timestamp by
10079 the indicated number of days. In both these steps the local time of day
10080 is kept the same. Finally, if there is a nonzero microseconds field, it
10081 is added or subtracted literally.
10082 When doing arithmetic on a <type>timestamp with time zone</type> value in
10083 a time zone that recognizes DST, this means that adding or subtracting
10084 (say) <literal>interval '1 day'</literal> does not necessarily have the
10085 same result as adding or subtracting <literal>interval '24
10086 hours'</literal>.
10087 For example, with the session time zone set
10088 to <literal>America/Denver</literal>:
10089 <screen>
10090 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day';
10091 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 12:00:00-06</computeroutput>
10092 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours';
10093 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 13:00:00-06</computeroutput>
10094 </screen>
10095 This happens because an hour was skipped due to a change in daylight saving
10096 time at <literal>2005-04-03 02:00:00</literal> in time zone
10097 <literal>America/Denver</literal>.
10098 </para>
10100 <para>
10101 Note there can be ambiguity in the <literal>months</literal> field returned by
10102 <function>age</function> because different months have different numbers of
10103 days. <productname>PostgreSQL</productname>'s approach uses the month from the
10104 earlier of the two dates when calculating partial months. For example,
10105 <literal>age('2004-06-01', '2004-04-30')</literal> uses April to yield
10106 <literal>1 mon 1 day</literal>, while using May would yield <literal>1 mon 2
10107 days</literal> because May has 31 days, while April has only 30.
10108 </para>
10110 <para>
10111 Subtraction of dates and timestamps can also be complex. One conceptually
10112 simple way to perform subtraction is to convert each value to a number
10113 of seconds using <literal>EXTRACT(EPOCH FROM ...)</literal>, then subtract the
10114 results; this produces the
10115 number of <emphasis>seconds</emphasis> between the two values. This will adjust
10116 for the number of days in each month, timezone changes, and daylight
10117 saving time adjustments. Subtraction of date or timestamp
10118 values with the <quote><literal>-</literal></quote> operator
10119 returns the number of days (24-hours) and hours/minutes/seconds
10120 between the values, making the same adjustments. The <function>age</function>
10121 function returns years, months, days, and hours/minutes/seconds,
10122 performing field-by-field subtraction and then adjusting for negative
10123 field values. The following queries illustrate the differences in these
10124 approaches. The sample results were produced with <literal>timezone
10125 = 'US/Eastern'</literal>; there is a daylight saving time change between the
10126 two dates used:
10127 </para>
10129 <screen>
10130 SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
10131 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
10132 <lineannotation>Result: </lineannotation><computeroutput>10537200.000000</computeroutput>
10133 SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
10134 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
10135 / 60 / 60 / 24;
10136 <lineannotation>Result: </lineannotation><computeroutput>121.9583333333333333</computeroutput>
10137 SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
10138 <lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
10139 SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
10140 <lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
10141 </screen>
10143 <sect2 id="functions-datetime-extract">
10144 <title><function>EXTRACT</function>, <function>date_part</function></title>
10146 <indexterm>
10147 <primary>date_part</primary>
10148 </indexterm>
10149 <indexterm>
10150 <primary>extract</primary>
10151 </indexterm>
10153 <synopsis>
10154 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
10155 </synopsis>
10157 <para>
10158 The <function>extract</function> function retrieves subfields
10159 such as year or hour from date/time values.
10160 <replaceable>source</replaceable> must be a value expression of
10161 type <type>timestamp</type>, <type>date</type>, <type>time</type>,
10162 or <type>interval</type>. (Timestamps and times can be with or
10163 without time zone.)
10164 <replaceable>field</replaceable> is an identifier or
10165 string that selects what field to extract from the source value.
10166 Not all fields are valid for every input data type; for example, fields
10167 smaller than a day cannot be extracted from a <type>date</type>, while
10168 fields of a day or more cannot be extracted from a <type>time</type>.
10169 The <function>extract</function> function returns values of type
10170 <type>numeric</type>.
10171 </para>
10173 <para>
10174 The following are valid field names:
10176 <!-- alphabetical -->
10177 <variablelist>
10178 <varlistentry>
10179 <term><literal>century</literal></term>
10180 <listitem>
10181 <para>
10182 The century; for <type>interval</type> values, the year field
10183 divided by 100
10184 </para>
10186 <screen>
10187 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
10188 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10189 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
10190 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
10191 SELECT EXTRACT(CENTURY FROM DATE '0001-01-01 AD');
10192 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10193 SELECT EXTRACT(CENTURY FROM DATE '0001-12-31 BC');
10194 <lineannotation>Result: </lineannotation><computeroutput>-1</computeroutput>
10195 SELECT EXTRACT(CENTURY FROM INTERVAL '2001 years');
10196 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10197 </screen>
10198 </listitem>
10199 </varlistentry>
10201 <varlistentry>
10202 <term><literal>day</literal></term>
10203 <listitem>
10204 <para>
10205 The day of the month (1&ndash;31); for <type>interval</type>
10206 values, the number of days
10207 </para>
10209 <screen>
10210 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
10211 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
10212 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
10213 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
10214 </screen>
10216 </listitem>
10217 </varlistentry>
10219 <varlistentry>
10220 <term><literal>decade</literal></term>
10221 <listitem>
10222 <para>
10223 The year field divided by 10
10224 </para>
10226 <screen>
10227 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
10228 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
10229 </screen>
10230 </listitem>
10231 </varlistentry>
10233 <varlistentry>
10234 <term><literal>dow</literal></term>
10235 <listitem>
10236 <para>
10237 The day of the week as Sunday (<literal>0</literal>) to
10238 Saturday (<literal>6</literal>)
10239 </para>
10241 <screen>
10242 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
10243 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
10244 </screen>
10245 <para>
10246 Note that <function>extract</function>'s day of the week numbering
10247 differs from that of the <function>to_char(...,
10248 'D')</function> function.
10249 </para>
10251 </listitem>
10252 </varlistentry>
10254 <varlistentry>
10255 <term><literal>doy</literal></term>
10256 <listitem>
10257 <para>
10258 The day of the year (1&ndash;365/366)
10259 </para>
10261 <screen>
10262 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
10263 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
10264 </screen>
10265 </listitem>
10266 </varlistentry>
10268 <varlistentry>
10269 <term><literal>epoch</literal></term>
10270 <listitem>
10271 <para>
10272 For <type>timestamp with time zone</type> values, the
10273 number of seconds since 1970-01-01 00:00:00 UTC (negative for
10274 timestamps before that);
10275 for <type>date</type> and <type>timestamp</type> values, the
10276 nominal number of seconds since 1970-01-01 00:00:00,
10277 without regard to timezone or daylight-savings rules;
10278 for <type>interval</type> values, the total number
10279 of seconds in the interval
10280 </para>
10282 <screen>
10283 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
10284 <lineannotation>Result: </lineannotation><computeroutput>982384720.120000</computeroutput>
10285 SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12');
10286 <lineannotation>Result: </lineannotation><computeroutput>982355920.120000</computeroutput>
10287 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
10288 <lineannotation>Result: </lineannotation><computeroutput>442800.000000</computeroutput>
10289 </screen>
10291 <para>
10292 You can convert an epoch value back to a <type>timestamp with time zone</type>
10293 with <function>to_timestamp</function>:
10294 </para>
10295 <screen>
10296 SELECT to_timestamp(982384720.12);
10297 <lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput>
10298 </screen>
10300 <para>
10301 Beware that applying <function>to_timestamp</function> to an epoch
10302 extracted from a <type>date</type> or <type>timestamp</type> value
10303 could produce a misleading result: the result will effectively
10304 assume that the original value had been given in UTC, which might
10305 not be the case.
10306 </para>
10307 </listitem>
10308 </varlistentry>
10310 <varlistentry>
10311 <term><literal>hour</literal></term>
10312 <listitem>
10313 <para>
10314 The hour field (0&ndash;23 in timestamps, unrestricted in
10315 intervals)
10316 </para>
10318 <screen>
10319 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
10320 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10321 </screen>
10322 </listitem>
10323 </varlistentry>
10325 <varlistentry>
10326 <term><literal>isodow</literal></term>
10327 <listitem>
10328 <para>
10329 The day of the week as Monday (<literal>1</literal>) to
10330 Sunday (<literal>7</literal>)
10331 </para>
10333 <screen>
10334 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
10335 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10336 </screen>
10337 <para>
10338 This is identical to <literal>dow</literal> except for Sunday. This
10339 matches the <acronym>ISO</acronym> 8601 day of the week numbering.
10340 </para>
10342 </listitem>
10343 </varlistentry>
10345 <varlistentry>
10346 <term><literal>isoyear</literal></term>
10347 <listitem>
10348 <para>
10349 The <acronym>ISO</acronym> 8601 week-numbering year that the date
10350 falls in
10351 </para>
10353 <screen>
10354 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
10355 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
10356 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
10357 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
10358 </screen>
10360 <para>
10361 Each <acronym>ISO</acronym> 8601 week-numbering year begins with the
10362 Monday of the week containing the 4th of January, so in early
10363 January or late December the <acronym>ISO</acronym> year may be
10364 different from the Gregorian year. See the <literal>week</literal>
10365 field for more information.
10366 </para>
10367 </listitem>
10368 </varlistentry>
10370 <varlistentry>
10371 <term><literal>julian</literal></term>
10372 <listitem>
10373 <para>
10374 The <firstterm>Julian Date</firstterm> corresponding to the
10375 date or timestamp. Timestamps
10376 that are not local midnight result in a fractional value. See
10377 <xref linkend="datetime-julian-dates"/> for more information.
10378 </para>
10380 <screen>
10381 SELECT EXTRACT(JULIAN FROM DATE '2006-01-01');
10382 <lineannotation>Result: </lineannotation><computeroutput>2453737</computeroutput>
10383 SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00');
10384 <lineannotation>Result: </lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
10385 </screen>
10386 </listitem>
10387 </varlistentry>
10389 <varlistentry>
10390 <term><literal>microseconds</literal></term>
10391 <listitem>
10392 <para>
10393 The seconds field, including fractional parts, multiplied by 1
10394 000 000; note that this includes full seconds
10395 </para>
10397 <screen>
10398 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
10399 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
10400 </screen>
10401 </listitem>
10402 </varlistentry>
10404 <varlistentry>
10405 <term><literal>millennium</literal></term>
10406 <listitem>
10407 <para>
10408 The millennium; for <type>interval</type> values, the year field
10409 divided by 1000
10410 </para>
10412 <screen>
10413 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
10414 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10415 SELECT EXTRACT(MILLENNIUM FROM INTERVAL '2001 years');
10416 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
10417 </screen>
10419 <para>
10420 Years in the 1900s are in the second millennium.
10421 The third millennium started January 1, 2001.
10422 </para>
10423 </listitem>
10424 </varlistentry>
10426 <varlistentry>
10427 <term><literal>milliseconds</literal></term>
10428 <listitem>
10429 <para>
10430 The seconds field, including fractional parts, multiplied by
10431 1000. Note that this includes full seconds.
10432 </para>
10434 <screen>
10435 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
10436 <lineannotation>Result: </lineannotation><computeroutput>28500.000</computeroutput>
10437 </screen>
10438 </listitem>
10439 </varlistentry>
10441 <varlistentry>
10442 <term><literal>minute</literal></term>
10443 <listitem>
10444 <para>
10445 The minutes field (0&ndash;59)
10446 </para>
10448 <screen>
10449 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
10450 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
10451 </screen>
10452 </listitem>
10453 </varlistentry>
10455 <varlistentry>
10456 <term><literal>month</literal></term>
10457 <listitem>
10458 <para>
10459 The number of the month within the year (1&ndash;12);
10460 for <type>interval</type> values, the number of months modulo 12
10461 (0&ndash;11)
10462 </para>
10464 <screen>
10465 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
10466 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
10467 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
10468 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10469 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
10470 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10471 </screen>
10472 </listitem>
10473 </varlistentry>
10475 <varlistentry>
10476 <term><literal>quarter</literal></term>
10477 <listitem>
10478 <para>
10479 The quarter of the year (1&ndash;4) that the date is in;
10480 for <type>interval</type> values, the month field divided by 3
10481 plus 1
10482 </para>
10484 <screen>
10485 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
10486 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10487 SELECT EXTRACT(QUARTER FROM INTERVAL '1 year 6 months');
10488 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10489 </screen>
10490 </listitem>
10491 </varlistentry>
10493 <varlistentry>
10494 <term><literal>second</literal></term>
10495 <listitem>
10496 <para>
10497 The seconds field, including any fractional seconds
10498 </para>
10500 <screen>
10501 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
10502 <lineannotation>Result: </lineannotation><computeroutput>40.000000</computeroutput>
10503 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
10504 <lineannotation>Result: </lineannotation><computeroutput>28.500000</computeroutput>
10505 </screen>
10506 </listitem>
10507 </varlistentry>
10508 <varlistentry>
10509 <term><literal>timezone</literal></term>
10510 <listitem>
10511 <para>
10512 The time zone offset from UTC, measured in seconds. Positive values
10513 correspond to time zones east of UTC, negative values to
10514 zones west of UTC. (Technically,
10515 <productname>PostgreSQL</productname> does not use UTC because
10516 leap seconds are not handled.)
10517 </para>
10518 </listitem>
10519 </varlistentry>
10521 <varlistentry>
10522 <term><literal>timezone_hour</literal></term>
10523 <listitem>
10524 <para>
10525 The hour component of the time zone offset
10526 </para>
10527 </listitem>
10528 </varlistentry>
10530 <varlistentry>
10531 <term><literal>timezone_minute</literal></term>
10532 <listitem>
10533 <para>
10534 The minute component of the time zone offset
10535 </para>
10536 </listitem>
10537 </varlistentry>
10539 <varlistentry>
10540 <term><literal>week</literal></term>
10541 <listitem>
10542 <para>
10543 The number of the <acronym>ISO</acronym> 8601 week-numbering week of
10544 the year. By definition, ISO weeks start on Mondays and the first
10545 week of a year contains January 4 of that year. In other words, the
10546 first Thursday of a year is in week 1 of that year.
10547 </para>
10548 <para>
10549 In the ISO week-numbering system, it is possible for early-January
10550 dates to be part of the 52nd or 53rd week of the previous year, and for
10551 late-December dates to be part of the first week of the next year.
10552 For example, <literal>2005-01-01</literal> is part of the 53rd week of year
10553 2004, and <literal>2006-01-01</literal> is part of the 52nd week of year
10554 2005, while <literal>2012-12-31</literal> is part of the first week of 2013.
10555 It's recommended to use the <literal>isoyear</literal> field together with
10556 <literal>week</literal> to get consistent results.
10557 </para>
10559 <para>
10560 For <type>interval</type> values, the week field is simply the number
10561 of integral days divided by 7.
10562 </para>
10564 <screen>
10565 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
10566 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10567 SELECT EXTRACT(WEEK FROM INTERVAL '13 days 24 hours');
10568 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10569 </screen>
10570 </listitem>
10571 </varlistentry>
10573 <varlistentry>
10574 <term><literal>year</literal></term>
10575 <listitem>
10576 <para>
10577 The year field. Keep in mind there is no <literal>0 AD</literal>, so subtracting
10578 <literal>BC</literal> years from <literal>AD</literal> years should be done with care.
10579 </para>
10581 <screen>
10582 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
10583 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
10584 </screen>
10585 </listitem>
10586 </varlistentry>
10588 </variablelist>
10589 </para>
10591 <para>
10592 When processing an <type>interval</type> value,
10593 the <function>extract</function> function produces field values that
10594 match the interpretation used by the interval output function. This
10595 can produce surprising results if one starts with a non-normalized
10596 interval representation, for example:
10597 <screen>
10598 SELECT INTERVAL '80 minutes';
10599 <lineannotation>Result: </lineannotation><computeroutput>01:20:00</computeroutput>
10600 SELECT EXTRACT(MINUTES FROM INTERVAL '80 minutes');
10601 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
10602 </screen>
10603 </para>
10605 <note>
10606 <para>
10607 When the input value is +/-Infinity, <function>extract</function> returns
10608 +/-Infinity for monotonically-increasing fields (<literal>epoch</literal>,
10609 <literal>julian</literal>, <literal>year</literal>, <literal>isoyear</literal>,
10610 <literal>decade</literal>, <literal>century</literal>, and <literal>millennium</literal>
10611 for <type>timestamp</type> inputs; <literal>epoch</literal>, <literal>hour</literal>,
10612 <literal>day</literal>, <literal>year</literal>, <literal>decade</literal>,
10613 <literal>century</literal>, and <literal>millennium</literal> for
10614 <type>interval</type> inputs).
10615 For other fields, NULL is returned. <productname>PostgreSQL</productname>
10616 versions before 9.6 returned zero for all cases of infinite input.
10617 </para>
10618 </note>
10620 <para>
10621 The <function>extract</function> function is primarily intended
10622 for computational processing. For formatting date/time values for
10623 display, see <xref linkend="functions-formatting"/>.
10624 </para>
10626 <para>
10627 The <function>date_part</function> function is modeled on the traditional
10628 <productname>Ingres</productname> equivalent to the
10629 <acronym>SQL</acronym>-standard function <function>extract</function>:
10630 <synopsis>
10631 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
10632 </synopsis>
10633 Note that here the <replaceable>field</replaceable> parameter needs to
10634 be a string value, not a name. The valid field names for
10635 <function>date_part</function> are the same as for
10636 <function>extract</function>.
10637 For historical reasons, the <function>date_part</function> function
10638 returns values of type <type>double precision</type>. This can result in
10639 a loss of precision in certain uses. Using <function>extract</function>
10640 is recommended instead.
10641 </para>
10643 <screen>
10644 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
10645 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
10646 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
10647 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
10648 </screen>
10650 </sect2>
10652 <sect2 id="functions-datetime-trunc">
10653 <title><function>date_trunc</function></title>
10655 <indexterm>
10656 <primary>date_trunc</primary>
10657 </indexterm>
10659 <para>
10660 The function <function>date_trunc</function> is conceptually
10661 similar to the <function>trunc</function> function for numbers.
10662 </para>
10664 <para>
10665 <synopsis>
10666 date_trunc(<replaceable>field</replaceable>, <replaceable>source</replaceable> <optional>, <replaceable>time_zone</replaceable> </optional>)
10667 </synopsis>
10668 <replaceable>source</replaceable> is a value expression of type
10669 <type>timestamp</type>, <type>timestamp with time zone</type>,
10670 or <type>interval</type>.
10671 (Values of type <type>date</type> and
10672 <type>time</type> are cast automatically to <type>timestamp</type> or
10673 <type>interval</type>, respectively.)
10674 <replaceable>field</replaceable> selects to which precision to
10675 truncate the input value. The return value is likewise of type
10676 <type>timestamp</type>, <type>timestamp with time zone</type>,
10677 or <type>interval</type>,
10678 and it has all fields that are less significant than the
10679 selected one set to zero (or one, for day and month).
10680 </para>
10682 <para>
10683 Valid values for <replaceable>field</replaceable> are:
10684 <simplelist>
10685 <member><literal>microseconds</literal></member>
10686 <member><literal>milliseconds</literal></member>
10687 <member><literal>second</literal></member>
10688 <member><literal>minute</literal></member>
10689 <member><literal>hour</literal></member>
10690 <member><literal>day</literal></member>
10691 <member><literal>week</literal></member>
10692 <member><literal>month</literal></member>
10693 <member><literal>quarter</literal></member>
10694 <member><literal>year</literal></member>
10695 <member><literal>decade</literal></member>
10696 <member><literal>century</literal></member>
10697 <member><literal>millennium</literal></member>
10698 </simplelist>
10699 </para>
10701 <para>
10702 When the input value is of type <type>timestamp with time zone</type>,
10703 the truncation is performed with respect to a particular time zone;
10704 for example, truncation to <literal>day</literal> produces a value that
10705 is midnight in that zone. By default, truncation is done with respect
10706 to the current <xref linkend="guc-timezone"/> setting, but the
10707 optional <replaceable>time_zone</replaceable> argument can be provided
10708 to specify a different time zone. The time zone name can be specified
10709 in any of the ways described in <xref linkend="datatype-timezones"/>.
10710 </para>
10712 <para>
10713 A time zone cannot be specified when processing <type>timestamp without
10714 time zone</type> or <type>interval</type> inputs. These are always
10715 taken at face value.
10716 </para>
10718 <para>
10719 Examples (assuming the local time zone is <literal>America/New_York</literal>):
10720 <screen>
10721 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
10722 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
10723 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
10724 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
10725 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
10726 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput>
10727 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
10728 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput>
10729 SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
10730 <lineannotation>Result: </lineannotation><computeroutput>3 days 02:00:00</computeroutput>
10731 </screen>
10732 </para>
10733 </sect2>
10735 <sect2 id="functions-datetime-bin">
10736 <title><function>date_bin</function></title>
10738 <indexterm>
10739 <primary>date_bin</primary>
10740 </indexterm>
10742 <para>
10743 The function <function>date_bin</function> <quote>bins</quote> the input
10744 timestamp into the specified interval (the <firstterm>stride</firstterm>)
10745 aligned with a specified origin.
10746 </para>
10748 <para>
10749 <synopsis>
10750 date_bin(<replaceable>stride</replaceable>, <replaceable>source</replaceable>, <replaceable>origin</replaceable>)
10751 </synopsis>
10752 <replaceable>source</replaceable> is a value expression of type
10753 <type>timestamp</type> or <type>timestamp with time zone</type>. (Values
10754 of type <type>date</type> are cast automatically to
10755 <type>timestamp</type>.) <replaceable>stride</replaceable> is a value
10756 expression of type <type>interval</type>. The return value is likewise
10757 of type <type>timestamp</type> or <type>timestamp with time zone</type>,
10758 and it marks the beginning of the bin into which the
10759 <replaceable>source</replaceable> is placed.
10760 </para>
10762 <para>
10763 Examples:
10764 <screen>
10765 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01');
10766 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:30:00</computeroutput>
10767 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30');
10768 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:32:30</computeroutput>
10769 </screen>
10770 </para>
10772 <para>
10773 In the case of full units (1 minute, 1 hour, etc.), it gives the same result as
10774 the analogous <function>date_trunc</function> call, but the difference is
10775 that <function>date_bin</function> can truncate to an arbitrary interval.
10776 </para>
10778 <para>
10779 The <parameter>stride</parameter> interval must be greater than zero and
10780 cannot contain units of month or larger.
10781 </para>
10782 </sect2>
10784 <sect2 id="functions-datetime-zoneconvert">
10785 <title><literal>AT TIME ZONE and AT LOCAL</literal></title>
10787 <indexterm>
10788 <primary>time zone</primary>
10789 <secondary>conversion</secondary>
10790 </indexterm>
10792 <indexterm>
10793 <primary>AT TIME ZONE</primary>
10794 </indexterm>
10796 <indexterm>
10797 <primary>AT LOCAL</primary>
10798 </indexterm>
10800 <para>
10801 The <literal>AT TIME ZONE</literal> operator converts time
10802 stamp <emphasis>without</emphasis> time zone to/from
10803 time stamp <emphasis>with</emphasis> time zone, and
10804 <type>time with time zone</type> values to different time
10805 zones. <xref linkend="functions-datetime-zoneconvert-table"/> shows its
10806 variants.
10807 </para>
10809 <table id="functions-datetime-zoneconvert-table">
10810 <title><literal>AT TIME ZONE</literal> and <literal>AT LOCAL</literal> Variants</title>
10811 <tgroup cols="1">
10812 <thead>
10813 <row>
10814 <entry role="func_table_entry"><para role="func_signature">
10815 Operator
10816 </para>
10817 <para>
10818 Description
10819 </para>
10820 <para>
10821 Example(s)
10822 </para></entry>
10823 </row>
10824 </thead>
10826 <tbody>
10827 <row>
10828 <entry role="func_table_entry"><para role="func_signature">
10829 <type>timestamp without time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10830 <returnvalue>timestamp with time zone</returnvalue>
10831 </para>
10832 <para>
10833 Converts given time stamp <emphasis>without</emphasis> time zone to
10834 time stamp <emphasis>with</emphasis> time zone, assuming the given
10835 value is in the named time zone.
10836 </para>
10837 <para>
10838 <literal>timestamp '2001-02-16 20:38:40' at time zone 'America/Denver'</literal>
10839 <returnvalue>2001-02-17 03:38:40+00</returnvalue>
10840 </para></entry>
10841 </row>
10843 <row>
10844 <entry role="func_table_entry"><para role="func_signature">
10845 <type>timestamp without time zone</type> <literal>AT LOCAL</literal>
10846 <returnvalue>timestamp with time zone</returnvalue>
10847 </para>
10848 <para>
10849 Converts given time stamp <emphasis>without</emphasis> time zone to
10850 time stamp <emphasis>with</emphasis> the session's
10851 <varname>TimeZone</varname> value as time zone.
10852 </para>
10853 <para>
10854 <literal>timestamp '2001-02-16 20:38:40' at local</literal>
10855 <returnvalue>2001-02-17 03:38:40+00</returnvalue>
10856 </para></entry>
10857 </row>
10859 <row>
10860 <entry role="func_table_entry"><para role="func_signature">
10861 <type>timestamp with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10862 <returnvalue>timestamp without time zone</returnvalue>
10863 </para>
10864 <para>
10865 Converts given time stamp <emphasis>with</emphasis> time zone to
10866 time stamp <emphasis>without</emphasis> time zone, as the time would
10867 appear in that zone.
10868 </para>
10869 <para>
10870 <literal>timestamp with time zone '2001-02-16 20:38:40-05' at time zone 'America/Denver'</literal>
10871 <returnvalue>2001-02-16 18:38:40</returnvalue>
10872 </para></entry>
10873 </row>
10875 <row>
10876 <entry role="func_table_entry"><para role="func_signature">
10877 <type>timestamp with time zone</type> <literal>AT LOCAL</literal>
10878 <returnvalue>timestamp without time zone</returnvalue>
10879 </para>
10880 <para>
10881 Converts given time stamp <emphasis>with</emphasis> time zone to
10882 time stamp <emphasis>without</emphasis> time zone, as the time would
10883 appear with the session's <varname>TimeZone</varname> value as time zone.
10884 </para>
10885 <para>
10886 <literal>timestamp with time zone '2001-02-16 20:38:40-05' at local</literal>
10887 <returnvalue>2001-02-16 18:38:40</returnvalue>
10888 </para></entry>
10889 </row>
10891 <row>
10892 <entry role="func_table_entry"><para role="func_signature">
10893 <type>time with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10894 <returnvalue>time with time zone</returnvalue>
10895 </para>
10896 <para>
10897 Converts given time <emphasis>with</emphasis> time zone to a new time
10898 zone. Since no date is supplied, this uses the currently active UTC
10899 offset for the named destination zone.
10900 </para>
10901 <para>
10902 <literal>time with time zone '05:34:17-05' at time zone 'UTC'</literal>
10903 <returnvalue>10:34:17+00</returnvalue>
10904 </para></entry>
10905 </row>
10907 <row>
10908 <entry role="func_table_entry"><para role="func_signature">
10909 <type>time with time zone</type> <literal>AT LOCAL</literal>
10910 <returnvalue>time with time zone</returnvalue>
10911 </para>
10912 <para>
10913 Converts given time <emphasis>with</emphasis> time zone to a new time
10914 zone. Since no date is supplied, this uses the currently active UTC
10915 offset for the session's <varname>TimeZone</varname> value.
10916 </para>
10917 <para>
10918 Assuming the session's <varname>TimeZone</varname> is set to <literal>UTC</literal>:
10919 </para>
10920 <para>
10921 <literal>time with time zone '05:34:17-05' at local</literal>
10922 <returnvalue>10:34:17+00</returnvalue>
10923 </para></entry>
10924 </row>
10925 </tbody>
10926 </tgroup>
10927 </table>
10929 <para>
10930 In these expressions, the desired time zone <replaceable>zone</replaceable> can be
10931 specified either as a text value (e.g., <literal>'America/Los_Angeles'</literal>)
10932 or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
10933 In the text case, a time zone name can be specified in any of the ways
10934 described in <xref linkend="datatype-timezones"/>.
10935 The interval case is only useful for zones that have fixed offsets from
10936 UTC, so it is not very common in practice.
10937 </para>
10939 <para>
10940 The syntax <literal>AT LOCAL</literal> may be used as shorthand for
10941 <literal>AT TIME ZONE <replaceable>local</replaceable></literal>, where
10942 <replaceable>local</replaceable> is the session's
10943 <varname>TimeZone</varname> value.
10944 </para>
10946 <para>
10947 Examples (assuming the current <xref linkend="guc-timezone"/> setting
10948 is <literal>America/Los_Angeles</literal>):
10949 <screen>
10950 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
10951 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
10952 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/Denver';
10953 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
10954 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
10955 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 05:38:40</computeroutput>
10956 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT LOCAL;
10957 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 17:38:40</computeroutput>
10958 SELECT TIME WITH TIME ZONE '20:38:40-05' AT LOCAL;
10959 <lineannotation>Result: </lineannotation><computeroutput>17:38:40</computeroutput>
10960 </screen>
10961 The first example adds a time zone to a value that lacks it, and
10962 displays the value using the current <varname>TimeZone</varname>
10963 setting. The second example shifts the time stamp with time zone value
10964 to the specified time zone, and returns the value without a time zone.
10965 This allows storage and display of values different from the current
10966 <varname>TimeZone</varname> setting. The third example converts
10967 Tokyo time to Chicago time. The fourth example shifts the time stamp
10968 with time zone value to the time zone currently specified by the
10969 <varname>TimeZone</varname> setting and returns the value without a
10970 time zone.
10971 </para>
10973 <para>
10974 The fifth example is a cautionary tale. Due to the fact that there is no
10975 date associated with the input value, the conversion is made using the
10976 current date of the session. Therefore, this static example may show a wrong
10977 result depending on the time of the year it is viewed because
10978 <literal>'America/Los_Angeles'</literal> observes Daylight Savings Time.
10979 </para>
10981 <para>
10982 The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
10983 <replaceable>timestamp</replaceable>)</literal> is equivalent to the SQL-conforming construct
10984 <literal><replaceable>timestamp</replaceable> AT TIME ZONE
10985 <replaceable>zone</replaceable></literal>.
10986 </para>
10988 <para>
10989 The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
10990 <replaceable>time</replaceable>)</literal> is equivalent to the SQL-conforming construct
10991 <literal><replaceable>time</replaceable> AT TIME ZONE
10992 <replaceable>zone</replaceable></literal>.
10993 </para>
10995 <para>
10996 The function <literal><function>timezone</function>(<replaceable>timestamp</replaceable>)</literal>
10997 is equivalent to the SQL-conforming construct <literal><replaceable>timestamp</replaceable>
10998 AT LOCAL</literal>.
10999 </para>
11001 <para>
11002 The function <literal><function>timezone</function>(<replaceable>time</replaceable>)</literal>
11003 is equivalent to the SQL-conforming construct <literal><replaceable>time</replaceable>
11004 AT LOCAL</literal>.
11005 </para>
11006 </sect2>
11008 <sect2 id="functions-datetime-current">
11009 <title>Current Date/Time</title>
11011 <indexterm>
11012 <primary>date</primary>
11013 <secondary>current</secondary>
11014 </indexterm>
11016 <indexterm>
11017 <primary>time</primary>
11018 <secondary>current</secondary>
11019 </indexterm>
11021 <para>
11022 <productname>PostgreSQL</productname> provides a number of functions
11023 that return values related to the current date and time. These
11024 SQL-standard functions all return values based on the start time of
11025 the current transaction:
11026 <synopsis>
11027 CURRENT_DATE
11028 CURRENT_TIME
11029 CURRENT_TIMESTAMP
11030 CURRENT_TIME(<replaceable>precision</replaceable>)
11031 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
11032 LOCALTIME
11033 LOCALTIMESTAMP
11034 LOCALTIME(<replaceable>precision</replaceable>)
11035 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
11036 </synopsis>
11037 </para>
11039 <para>
11040 <function>CURRENT_TIME</function> and
11041 <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
11042 <function>LOCALTIME</function> and
11043 <function>LOCALTIMESTAMP</function> deliver values without time zone.
11044 </para>
11046 <para>
11047 <function>CURRENT_TIME</function>,
11048 <function>CURRENT_TIMESTAMP</function>,
11049 <function>LOCALTIME</function>, and
11050 <function>LOCALTIMESTAMP</function>
11051 can optionally take
11052 a precision parameter, which causes the result to be rounded
11053 to that many fractional digits in the seconds field. Without a precision parameter,
11054 the result is given to the full available precision.
11055 </para>
11057 <para>
11058 Some examples:
11059 <screen>
11060 SELECT CURRENT_TIME;
11061 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
11062 SELECT CURRENT_DATE;
11063 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23</computeroutput>
11064 SELECT CURRENT_TIMESTAMP;
11065 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522-05</computeroutput>
11066 SELECT CURRENT_TIMESTAMP(2);
11067 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.66-05</computeroutput>
11068 SELECT LOCALTIMESTAMP;
11069 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522</computeroutput>
11070 </screen>
11071 </para>
11073 <para>
11074 Since these functions return
11075 the start time of the current transaction, their values do not
11076 change during the transaction. This is considered a feature:
11077 the intent is to allow a single transaction to have a consistent
11078 notion of the <quote>current</quote> time, so that multiple
11079 modifications within the same transaction bear the same
11080 time stamp.
11081 </para>
11083 <note>
11084 <para>
11085 Other database systems might advance these values more
11086 frequently.
11087 </para>
11088 </note>
11090 <para>
11091 <productname>PostgreSQL</productname> also provides functions that
11092 return the start time of the current statement, as well as the actual
11093 current time at the instant the function is called. The complete list
11094 of non-SQL-standard time functions is:
11095 <synopsis>
11096 transaction_timestamp()
11097 statement_timestamp()
11098 clock_timestamp()
11099 timeofday()
11100 now()
11101 </synopsis>
11102 </para>
11104 <para>
11105 <function>transaction_timestamp()</function> is equivalent to
11106 <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
11107 what it returns.
11108 <function>statement_timestamp()</function> returns the start time of the current
11109 statement (more specifically, the time of receipt of the latest command
11110 message from the client).
11111 <function>statement_timestamp()</function> and <function>transaction_timestamp()</function>
11112 return the same value during the first command of a transaction, but might
11113 differ during subsequent commands.
11114 <function>clock_timestamp()</function> returns the actual current time, and
11115 therefore its value changes even within a single SQL command.
11116 <function>timeofday()</function> is a historical
11117 <productname>PostgreSQL</productname> function. Like
11118 <function>clock_timestamp()</function>, it returns the actual current time,
11119 but as a formatted <type>text</type> string rather than a <type>timestamp
11120 with time zone</type> value.
11121 <function>now()</function> is a traditional <productname>PostgreSQL</productname>
11122 equivalent to <function>transaction_timestamp()</function>.
11123 </para>
11125 <para>
11126 All the date/time data types also accept the special literal value
11127 <literal>now</literal> to specify the current date and time (again,
11128 interpreted as the transaction start time). Thus,
11129 the following three all return the same result:
11130 <programlisting>
11131 SELECT CURRENT_TIMESTAMP;
11132 SELECT now();
11133 SELECT TIMESTAMP 'now'; -- but see tip below
11134 </programlisting>
11135 </para>
11137 <tip>
11138 <para>
11139 Do not use the third form when specifying a value to be evaluated later,
11140 for example in a <literal>DEFAULT</literal> clause for a table column.
11141 The system will convert <literal>now</literal>
11142 to a <type>timestamp</type> as soon as the constant is parsed, so that when
11143 the default value is needed,
11144 the time of the table creation would be used! The first two
11145 forms will not be evaluated until the default value is used,
11146 because they are function calls. Thus they will give the desired
11147 behavior of defaulting to the time of row insertion.
11148 (See also <xref linkend="datatype-datetime-special-values"/>.)
11149 </para>
11150 </tip>
11151 </sect2>
11153 <sect2 id="functions-datetime-delay">
11154 <title>Delaying Execution</title>
11156 <indexterm>
11157 <primary>pg_sleep</primary>
11158 </indexterm>
11159 <indexterm>
11160 <primary>pg_sleep_for</primary>
11161 </indexterm>
11162 <indexterm>
11163 <primary>pg_sleep_until</primary>
11164 </indexterm>
11165 <indexterm>
11166 <primary>sleep</primary>
11167 </indexterm>
11168 <indexterm>
11169 <primary>delay</primary>
11170 </indexterm>
11172 <para>
11173 The following functions are available to delay execution of the server
11174 process:
11175 <synopsis>
11176 pg_sleep ( <type>double precision</type> )
11177 pg_sleep_for ( <type>interval</type> )
11178 pg_sleep_until ( <type>timestamp with time zone</type> )
11179 </synopsis>
11181 <function>pg_sleep</function> makes the current session's process
11182 sleep until the given number of seconds have
11183 elapsed. Fractional-second delays can be specified.
11184 <function>pg_sleep_for</function> is a convenience function to
11185 allow the sleep time to be specified as an <type>interval</type>.
11186 <function>pg_sleep_until</function> is a convenience function for when
11187 a specific wake-up time is desired.
11188 For example:
11190 <programlisting>
11191 SELECT pg_sleep(1.5);
11192 SELECT pg_sleep_for('5 minutes');
11193 SELECT pg_sleep_until('tomorrow 03:00');
11194 </programlisting>
11195 </para>
11197 <note>
11198 <para>
11199 The effective resolution of the sleep interval is platform-specific;
11200 0.01 seconds is a common value. The sleep delay will be at least as long
11201 as specified. It might be longer depending on factors such as server load.
11202 In particular, <function>pg_sleep_until</function> is not guaranteed to
11203 wake up exactly at the specified time, but it will not wake up any earlier.
11204 </para>
11205 </note>
11207 <warning>
11208 <para>
11209 Make sure that your session does not hold more locks than necessary
11210 when calling <function>pg_sleep</function> or its variants. Otherwise
11211 other sessions might have to wait for your sleeping process, slowing down
11212 the entire system.
11213 </para>
11214 </warning>
11215 </sect2>
11217 </sect1>
11220 <sect1 id="functions-enum">
11221 <title>Enum Support Functions</title>
11223 <para>
11224 For enum types (described in <xref linkend="datatype-enum"/>),
11225 there are several functions that allow cleaner programming without
11226 hard-coding particular values of an enum type.
11227 These are listed in <xref linkend="functions-enum-table"/>. The examples
11228 assume an enum type created as:
11230 <programlisting>
11231 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
11232 </programlisting>
11234 </para>
11236 <table id="functions-enum-table">
11237 <title>Enum Support Functions</title>
11238 <tgroup cols="1">
11239 <thead>
11240 <row>
11241 <entry role="func_table_entry"><para role="func_signature">
11242 Function
11243 </para>
11244 <para>
11245 Description
11246 </para>
11247 <para>
11248 Example(s)
11249 </para></entry>
11250 </row>
11251 </thead>
11253 <tbody>
11254 <row>
11255 <entry role="func_table_entry"><para role="func_signature">
11256 <indexterm>
11257 <primary>enum_first</primary>
11258 </indexterm>
11259 <function>enum_first</function> ( <type>anyenum</type> )
11260 <returnvalue>anyenum</returnvalue>
11261 </para>
11262 <para>
11263 Returns the first value of the input enum type.
11264 </para>
11265 <para>
11266 <literal>enum_first(null::rainbow)</literal>
11267 <returnvalue>red</returnvalue>
11268 </para></entry>
11269 </row>
11270 <row>
11271 <entry role="func_table_entry"><para role="func_signature">
11272 <indexterm>
11273 <primary>enum_last</primary>
11274 </indexterm>
11275 <function>enum_last</function> ( <type>anyenum</type> )
11276 <returnvalue>anyenum</returnvalue>
11277 </para>
11278 <para>
11279 Returns the last value of the input enum type.
11280 </para>
11281 <para>
11282 <literal>enum_last(null::rainbow)</literal>
11283 <returnvalue>purple</returnvalue>
11284 </para></entry>
11285 </row>
11286 <row>
11287 <entry role="func_table_entry"><para role="func_signature">
11288 <indexterm>
11289 <primary>enum_range</primary>
11290 </indexterm>
11291 <function>enum_range</function> ( <type>anyenum</type> )
11292 <returnvalue>anyarray</returnvalue>
11293 </para>
11294 <para>
11295 Returns all values of the input enum type in an ordered array.
11296 </para>
11297 <para>
11298 <literal>enum_range(null::rainbow)</literal>
11299 <returnvalue>{red,orange,yellow,&zwsp;green,blue,purple}</returnvalue>
11300 </para></entry>
11301 </row>
11302 <row>
11303 <entry role="func_table_entry"><para role="func_signature">
11304 <function>enum_range</function> ( <type>anyenum</type>, <type>anyenum</type> )
11305 <returnvalue>anyarray</returnvalue>
11306 </para>
11307 <para>
11308 Returns the range between the two given enum values, as an ordered
11309 array. The values must be from the same enum type. If the first
11310 parameter is null, the result will start with the first value of
11311 the enum type.
11312 If the second parameter is null, the result will end with the last
11313 value of the enum type.
11314 </para>
11315 <para>
11316 <literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal>
11317 <returnvalue>{orange,yellow,green}</returnvalue>
11318 </para>
11319 <para>
11320 <literal>enum_range(NULL, 'green'::rainbow)</literal>
11321 <returnvalue>{red,orange,&zwsp;yellow,green}</returnvalue>
11322 </para>
11323 <para>
11324 <literal>enum_range('orange'::rainbow, NULL)</literal>
11325 <returnvalue>{orange,yellow,green,&zwsp;blue,purple}</returnvalue>
11326 </para></entry>
11327 </row>
11328 </tbody>
11329 </tgroup>
11330 </table>
11332 <para>
11333 Notice that except for the two-argument form of <function>enum_range</function>,
11334 these functions disregard the specific value passed to them; they care
11335 only about its declared data type. Either null or a specific value of
11336 the type can be passed, with the same result. It is more common to
11337 apply these functions to a table column or function argument than to
11338 a hardwired type name as used in the examples.
11339 </para>
11340 </sect1>
11342 <sect1 id="functions-geometry">
11343 <title>Geometric Functions and Operators</title>
11345 <para>
11346 The geometric types <type>point</type>, <type>box</type>,
11347 <type>lseg</type>, <type>line</type>, <type>path</type>,
11348 <type>polygon</type>, and <type>circle</type> have a large set of
11349 native support functions and operators, shown in <xref
11350 linkend="functions-geometry-op-table"/>, <xref
11351 linkend="functions-geometry-func-table"/>, and <xref
11352 linkend="functions-geometry-conv-table"/>.
11353 </para>
11355 <table id="functions-geometry-op-table">
11356 <title>Geometric Operators</title>
11357 <tgroup cols="1">
11358 <thead>
11359 <row>
11360 <entry role="func_table_entry"><para role="func_signature">
11361 Operator
11362 </para>
11363 <para>
11364 Description
11365 </para>
11366 <para>
11367 Example(s)
11368 </para></entry>
11369 </row>
11370 </thead>
11372 <tbody>
11373 <row>
11374 <entry role="func_table_entry"><para role="func_signature">
11375 <replaceable>geometric_type</replaceable> <literal>+</literal> <type>point</type>
11376 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11377 </para>
11378 <para>
11379 Adds the coordinates of the second <type>point</type> to those of each
11380 point of the first argument, thus performing translation.
11381 Available for <type>point</type>, <type>box</type>, <type>path</type>,
11382 <type>circle</type>.
11383 </para>
11384 <para>
11385 <literal>box '(1,1),(0,0)' + point '(2,0)'</literal>
11386 <returnvalue>(3,1),(2,0)</returnvalue>
11387 </para></entry>
11388 </row>
11390 <row>
11391 <entry role="func_table_entry"><para role="func_signature">
11392 <type>path</type> <literal>+</literal> <type>path</type>
11393 <returnvalue>path</returnvalue>
11394 </para>
11395 <para>
11396 Concatenates two open paths (returns NULL if either path is closed).
11397 </para>
11398 <para>
11399 <literal>path '[(0,0),(1,1)]' + path '[(2,2),(3,3),(4,4)]'</literal>
11400 <returnvalue>[(0,0),(1,1),(2,2),(3,3),(4,4)]</returnvalue>
11401 </para></entry>
11402 </row>
11404 <row>
11405 <entry role="func_table_entry"><para role="func_signature">
11406 <replaceable>geometric_type</replaceable> <literal>-</literal> <type>point</type>
11407 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11408 </para>
11409 <para>
11410 Subtracts the coordinates of the second <type>point</type> from those
11411 of each point of the first argument, thus performing translation.
11412 Available for <type>point</type>, <type>box</type>, <type>path</type>,
11413 <type>circle</type>.
11414 </para>
11415 <para>
11416 <literal>box '(1,1),(0,0)' - point '(2,0)'</literal>
11417 <returnvalue>(-1,1),(-2,0)</returnvalue>
11418 </para></entry>
11419 </row>
11421 <row>
11422 <entry role="func_table_entry"><para role="func_signature">
11423 <replaceable>geometric_type</replaceable> <literal>*</literal> <type>point</type>
11424 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11425 </para>
11426 <para>
11427 Multiplies each point of the first argument by the second
11428 <type>point</type> (treating a point as being a complex number
11429 represented by real and imaginary parts, and performing standard
11430 complex multiplication). If one interprets
11431 the second <type>point</type> as a vector, this is equivalent to
11432 scaling the object's size and distance from the origin by the length
11433 of the vector, and rotating it counterclockwise around the origin by
11434 the vector's angle from the <replaceable>x</replaceable> axis.
11435 Available for <type>point</type>, <type>box</type>,<footnote
11436 id="functions-geometry-rotation-fn"><para><quote>Rotating</quote> a
11437 box with these operators only moves its corner points: the box is
11438 still considered to have sides parallel to the axes. Hence the box's
11439 size is not preserved, as a true rotation would do.</para></footnote>
11440 <type>path</type>, <type>circle</type>.
11441 </para>
11442 <para>
11443 <literal>path '((0,0),(1,0),(1,1))' * point '(3.0,0)'</literal>
11444 <returnvalue>((0,0),(3,0),(3,3))</returnvalue>
11445 </para>
11446 <para>
11447 <literal>path '((0,0),(1,0),(1,1))' * point(cosd(45), sind(45))</literal>
11448 <returnvalue>((0,0),&zwsp;(0.7071067811865475,0.7071067811865475),&zwsp;(0,1.414213562373095))</returnvalue>
11449 </para></entry>
11450 </row>
11452 <row>
11453 <entry role="func_table_entry"><para role="func_signature">
11454 <replaceable>geometric_type</replaceable> <literal>/</literal> <type>point</type>
11455 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11456 </para>
11457 <para>
11458 Divides each point of the first argument by the second
11459 <type>point</type> (treating a point as being a complex number
11460 represented by real and imaginary parts, and performing standard
11461 complex division). If one interprets
11462 the second <type>point</type> as a vector, this is equivalent to
11463 scaling the object's size and distance from the origin down by the
11464 length of the vector, and rotating it clockwise around the origin by
11465 the vector's angle from the <replaceable>x</replaceable> axis.
11466 Available for <type>point</type>, <type>box</type>,<footnoteref
11467 linkend="functions-geometry-rotation-fn"/> <type>path</type>,
11468 <type>circle</type>.
11469 </para>
11470 <para>
11471 <literal>path '((0,0),(1,0),(1,1))' / point '(2.0,0)'</literal>
11472 <returnvalue>((0,0),(0.5,0),(0.5,0.5))</returnvalue>
11473 </para>
11474 <para>
11475 <literal>path '((0,0),(1,0),(1,1))' / point(cosd(45), sind(45))</literal>
11476 <returnvalue>((0,0),&zwsp;(0.7071067811865476,-0.7071067811865476),&zwsp;(1.4142135623730951,0))</returnvalue>
11477 </para></entry>
11478 </row>
11480 <row>
11481 <entry role="func_table_entry"><para role="func_signature">
11482 <literal>@-@</literal> <replaceable>geometric_type</replaceable>
11483 <returnvalue>double precision</returnvalue>
11484 </para>
11485 <para>
11486 Computes the total length.
11487 Available for <type>lseg</type>, <type>path</type>.
11488 </para>
11489 <para>
11490 <literal>@-@ path '[(0,0),(1,0),(1,1)]'</literal>
11491 <returnvalue>2</returnvalue>
11492 </para></entry>
11493 </row>
11495 <row>
11496 <entry role="func_table_entry"><para role="func_signature">
11497 <literal>@@</literal> <replaceable>geometric_type</replaceable>
11498 <returnvalue>point</returnvalue>
11499 </para>
11500 <para>
11501 Computes the center point.
11502 Available for <type>box</type>, <type>lseg</type>,
11503 <type>polygon</type>, <type>circle</type>.
11504 </para>
11505 <para>
11506 <literal>@@ box '(2,2),(0,0)'</literal>
11507 <returnvalue>(1,1)</returnvalue>
11508 </para></entry>
11509 </row>
11511 <row>
11512 <entry role="func_table_entry"><para role="func_signature">
11513 <literal>#</literal> <replaceable>geometric_type</replaceable>
11514 <returnvalue>integer</returnvalue>
11515 </para>
11516 <para>
11517 Returns the number of points.
11518 Available for <type>path</type>, <type>polygon</type>.
11519 </para>
11520 <para>
11521 <literal># path '((1,0),(0,1),(-1,0))'</literal>
11522 <returnvalue>3</returnvalue>
11523 </para></entry>
11524 </row>
11526 <row>
11527 <entry role="func_table_entry"><para role="func_signature">
11528 <replaceable>geometric_type</replaceable> <literal>#</literal> <replaceable>geometric_type</replaceable>
11529 <returnvalue>point</returnvalue>
11530 </para>
11531 <para>
11532 Computes the point of intersection, or NULL if there is none.
11533 Available for <type>lseg</type>, <type>line</type>.
11534 </para>
11535 <para>
11536 <literal>lseg '[(0,0),(1,1)]' # lseg '[(1,0),(0,1)]'</literal>
11537 <returnvalue>(0.5,0.5)</returnvalue>
11538 </para></entry>
11539 </row>
11541 <row>
11542 <entry role="func_table_entry"><para role="func_signature">
11543 <type>box</type> <literal>#</literal> <type>box</type>
11544 <returnvalue>box</returnvalue>
11545 </para>
11546 <para>
11547 Computes the intersection of two boxes, or NULL if there is none.
11548 </para>
11549 <para>
11550 <literal>box '(2,2),(-1,-1)' # box '(1,1),(-2,-2)'</literal>
11551 <returnvalue>(1,1),(-1,-1)</returnvalue>
11552 </para></entry>
11553 </row>
11555 <row>
11556 <entry role="func_table_entry"><para role="func_signature">
11557 <replaceable>geometric_type</replaceable> <literal>##</literal> <replaceable>geometric_type</replaceable>
11558 <returnvalue>point</returnvalue>
11559 </para>
11560 <para>
11561 Computes the closest point to the first object on the second object.
11562 Available for these pairs of types:
11563 (<type>point</type>, <type>box</type>),
11564 (<type>point</type>, <type>lseg</type>),
11565 (<type>point</type>, <type>line</type>),
11566 (<type>lseg</type>, <type>box</type>),
11567 (<type>lseg</type>, <type>lseg</type>),
11568 (<type>line</type>, <type>lseg</type>).
11569 </para>
11570 <para>
11571 <literal>point '(0,0)' ## lseg '[(2,0),(0,2)]'</literal>
11572 <returnvalue>(1,1)</returnvalue>
11573 </para></entry>
11574 </row>
11576 <row>
11577 <entry role="func_table_entry"><para role="func_signature">
11578 <replaceable>geometric_type</replaceable> <literal>&lt;-&gt;</literal> <replaceable>geometric_type</replaceable>
11579 <returnvalue>double precision</returnvalue>
11580 </para>
11581 <para>
11582 Computes the distance between the objects.
11583 Available for all seven geometric types, for all combinations
11584 of <type>point</type> with another geometric type, and for
11585 these additional pairs of types:
11586 (<type>box</type>, <type>lseg</type>),
11587 (<type>lseg</type>, <type>line</type>),
11588 (<type>polygon</type>, <type>circle</type>)
11589 (and the commutator cases).
11590 </para>
11591 <para>
11592 <literal>circle '&lt;(0,0),1&gt;' &lt;-&gt; circle '&lt;(5,0),1&gt;'</literal>
11593 <returnvalue>3</returnvalue>
11594 </para></entry>
11595 </row>
11597 <row>
11598 <entry role="func_table_entry"><para role="func_signature">
11599 <replaceable>geometric_type</replaceable> <literal>@&gt;</literal> <replaceable>geometric_type</replaceable>
11600 <returnvalue>boolean</returnvalue>
11601 </para>
11602 <para>
11603 Does first object contain second?
11604 Available for these pairs of types:
11605 (<literal>box</literal>, <literal>point</literal>),
11606 (<literal>box</literal>, <literal>box</literal>),
11607 (<literal>path</literal>, <literal>point</literal>),
11608 (<literal>polygon</literal>, <literal>point</literal>),
11609 (<literal>polygon</literal>, <literal>polygon</literal>),
11610 (<literal>circle</literal>, <literal>point</literal>),
11611 (<literal>circle</literal>, <literal>circle</literal>).
11612 </para>
11613 <para>
11614 <literal>circle '&lt;(0,0),2&gt;' @&gt; point '(1,1)'</literal>
11615 <returnvalue>t</returnvalue>
11616 </para></entry>
11617 </row>
11619 <row>
11620 <entry role="func_table_entry"><para role="func_signature">
11621 <replaceable>geometric_type</replaceable> <literal>&lt;@</literal> <replaceable>geometric_type</replaceable>
11622 <returnvalue>boolean</returnvalue>
11623 </para>
11624 <para>
11625 Is first object contained in or on second?
11626 Available for these pairs of types:
11627 (<literal>point</literal>, <literal>box</literal>),
11628 (<literal>point</literal>, <literal>lseg</literal>),
11629 (<literal>point</literal>, <literal>line</literal>),
11630 (<literal>point</literal>, <literal>path</literal>),
11631 (<literal>point</literal>, <literal>polygon</literal>),
11632 (<literal>point</literal>, <literal>circle</literal>),
11633 (<literal>box</literal>, <literal>box</literal>),
11634 (<literal>lseg</literal>, <literal>box</literal>),
11635 (<literal>lseg</literal>, <literal>line</literal>),
11636 (<literal>polygon</literal>, <literal>polygon</literal>),
11637 (<literal>circle</literal>, <literal>circle</literal>).
11638 </para>
11639 <para>
11640 <literal>point '(1,1)' &lt;@ circle '&lt;(0,0),2&gt;'</literal>
11641 <returnvalue>t</returnvalue>
11642 </para></entry>
11643 </row>
11645 <row>
11646 <entry role="func_table_entry"><para role="func_signature">
11647 <replaceable>geometric_type</replaceable> <literal>&amp;&amp;</literal> <replaceable>geometric_type</replaceable>
11648 <returnvalue>boolean</returnvalue>
11649 </para>
11650 <para>
11651 Do these objects overlap? (One point in common makes this true.)
11652 Available for <type>box</type>, <type>polygon</type>,
11653 <type>circle</type>.
11654 </para>
11655 <para>
11656 <literal>box '(1,1),(0,0)' &amp;&amp; box '(2,2),(0,0)'</literal>
11657 <returnvalue>t</returnvalue>
11658 </para></entry>
11659 </row>
11661 <row>
11662 <entry role="func_table_entry"><para role="func_signature">
11663 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;</literal> <replaceable>geometric_type</replaceable>
11664 <returnvalue>boolean</returnvalue>
11665 </para>
11666 <para>
11667 Is first object strictly left of second?
11668 Available for <type>point</type>, <type>box</type>,
11669 <type>polygon</type>, <type>circle</type>.
11670 </para>
11671 <para>
11672 <literal>circle '&lt;(0,0),1&gt;' &lt;&lt; circle '&lt;(5,0),1&gt;'</literal>
11673 <returnvalue>t</returnvalue>
11674 </para></entry>
11675 </row>
11677 <row>
11678 <entry role="func_table_entry"><para role="func_signature">
11679 <replaceable>geometric_type</replaceable> <literal>&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11680 <returnvalue>boolean</returnvalue>
11681 </para>
11682 <para>
11683 Is first object strictly right of second?
11684 Available for <type>point</type>, <type>box</type>,
11685 <type>polygon</type>, <type>circle</type>.
11686 </para>
11687 <para>
11688 <literal>circle '&lt;(5,0),1&gt;' &gt;&gt; circle '&lt;(0,0),1&gt;'</literal>
11689 <returnvalue>t</returnvalue>
11690 </para></entry>
11691 </row>
11693 <row>
11694 <entry role="func_table_entry"><para role="func_signature">
11695 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;</literal> <replaceable>geometric_type</replaceable>
11696 <returnvalue>boolean</returnvalue>
11697 </para>
11698 <para>
11699 Does first object not extend to the right of second?
11700 Available for <type>box</type>, <type>polygon</type>,
11701 <type>circle</type>.
11702 </para>
11703 <para>
11704 <literal>box '(1,1),(0,0)' &amp;&lt; box '(2,2),(0,0)'</literal>
11705 <returnvalue>t</returnvalue>
11706 </para></entry>
11707 </row>
11709 <row>
11710 <entry role="func_table_entry"><para role="func_signature">
11711 <replaceable>geometric_type</replaceable> <literal>&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11712 <returnvalue>boolean</returnvalue>
11713 </para>
11714 <para>
11715 Does first object not extend to the left of second?
11716 Available for <type>box</type>, <type>polygon</type>,
11717 <type>circle</type>.
11718 </para>
11719 <para>
11720 <literal>box '(3,3),(0,0)' &amp;&gt; box '(2,2),(0,0)'</literal>
11721 <returnvalue>t</returnvalue>
11722 </para></entry>
11723 </row>
11725 <row>
11726 <entry role="func_table_entry"><para role="func_signature">
11727 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;|</literal> <replaceable>geometric_type</replaceable>
11728 <returnvalue>boolean</returnvalue>
11729 </para>
11730 <para>
11731 Is first object strictly below second?
11732 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11733 <type>circle</type>.
11734 </para>
11735 <para>
11736 <literal>box '(3,3),(0,0)' &lt;&lt;| box '(5,5),(3,4)'</literal>
11737 <returnvalue>t</returnvalue>
11738 </para></entry>
11739 </row>
11741 <row>
11742 <entry role="func_table_entry"><para role="func_signature">
11743 <replaceable>geometric_type</replaceable> <literal>|&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11744 <returnvalue>boolean</returnvalue>
11745 </para>
11746 <para>
11747 Is first object strictly above second?
11748 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11749 <type>circle</type>.
11750 </para>
11751 <para>
11752 <literal>box '(5,5),(3,4)' |&gt;&gt; box '(3,3),(0,0)'</literal>
11753 <returnvalue>t</returnvalue>
11754 </para></entry>
11755 </row>
11757 <row>
11758 <entry role="func_table_entry"><para role="func_signature">
11759 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;|</literal> <replaceable>geometric_type</replaceable>
11760 <returnvalue>boolean</returnvalue>
11761 </para>
11762 <para>
11763 Does first object not extend above second?
11764 Available for <type>box</type>, <type>polygon</type>,
11765 <type>circle</type>.
11766 </para>
11767 <para>
11768 <literal>box '(1,1),(0,0)' &amp;&lt;| box '(2,2),(0,0)'</literal>
11769 <returnvalue>t</returnvalue>
11770 </para></entry>
11771 </row>
11773 <row>
11774 <entry role="func_table_entry"><para role="func_signature">
11775 <replaceable>geometric_type</replaceable> <literal>|&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11776 <returnvalue>boolean</returnvalue>
11777 </para>
11778 <para>
11779 Does first object not extend below second?
11780 Available for <type>box</type>, <type>polygon</type>,
11781 <type>circle</type>.
11782 </para>
11783 <para>
11784 <literal>box '(3,3),(0,0)' |&amp;&gt; box '(2,2),(0,0)'</literal>
11785 <returnvalue>t</returnvalue>
11786 </para></entry>
11787 </row>
11789 <row>
11790 <entry role="func_table_entry"><para role="func_signature">
11791 <type>box</type> <literal>&lt;^</literal> <type>box</type>
11792 <returnvalue>boolean</returnvalue>
11793 </para>
11794 <para>
11795 Is first object below second (allows edges to touch)?
11796 </para>
11797 <para>
11798 <literal>box '((1,1),(0,0))' &lt;^ box '((2,2),(1,1))'</literal>
11799 <returnvalue>t</returnvalue>
11800 </para></entry>
11801 </row>
11803 <row>
11804 <entry role="func_table_entry"><para role="func_signature">
11805 <type>box</type> <literal>&gt;^</literal> <type>box</type>
11806 <returnvalue>boolean</returnvalue>
11807 </para>
11808 <para>
11809 Is first object above second (allows edges to touch)?
11810 </para>
11811 <para>
11812 <literal>box '((2,2),(1,1))' &gt;^ box '((1,1),(0,0))'</literal>
11813 <returnvalue>t</returnvalue>
11814 </para></entry>
11815 </row>
11817 <row>
11818 <entry role="func_table_entry"><para role="func_signature">
11819 <replaceable>geometric_type</replaceable> <literal>?#</literal> <replaceable>geometric_type</replaceable>
11820 <returnvalue>boolean</returnvalue>
11821 </para>
11822 <para>
11823 Do these objects intersect?
11824 Available for these pairs of types:
11825 (<type>box</type>, <type>box</type>),
11826 (<type>lseg</type>, <type>box</type>),
11827 (<type>lseg</type>, <type>lseg</type>),
11828 (<type>lseg</type>, <type>line</type>),
11829 (<type>line</type>, <type>box</type>),
11830 (<type>line</type>, <type>line</type>),
11831 (<type>path</type>, <type>path</type>).
11832 </para>
11833 <para>
11834 <literal>lseg '[(-1,0),(1,0)]' ?# box '(2,2),(-2,-2)'</literal>
11835 <returnvalue>t</returnvalue>
11836 </para></entry>
11837 </row>
11839 <row>
11840 <entry role="func_table_entry"><para role="func_signature">
11841 <literal>?-</literal> <type>line</type>
11842 <returnvalue>boolean</returnvalue>
11843 </para>
11844 <para role="func_signature">
11845 <literal>?-</literal> <type>lseg</type>
11846 <returnvalue>boolean</returnvalue>
11847 </para>
11848 <para>
11849 Is line horizontal?
11850 </para>
11851 <para>
11852 <literal>?- lseg '[(-1,0),(1,0)]'</literal>
11853 <returnvalue>t</returnvalue>
11854 </para></entry>
11855 </row>
11857 <row>
11858 <entry role="func_table_entry"><para role="func_signature">
11859 <type>point</type> <literal>?-</literal> <type>point</type>
11860 <returnvalue>boolean</returnvalue>
11861 </para>
11862 <para>
11863 Are points horizontally aligned (that is, have same y coordinate)?
11864 </para>
11865 <para>
11866 <literal>point '(1,0)' ?- point '(0,0)'</literal>
11867 <returnvalue>t</returnvalue>
11868 </para></entry>
11869 </row>
11871 <row>
11872 <entry role="func_table_entry"><para role="func_signature">
11873 <literal>?|</literal> <type>line</type>
11874 <returnvalue>boolean</returnvalue>
11875 </para>
11876 <para role="func_signature">
11877 <literal>?|</literal> <type>lseg</type>
11878 <returnvalue>boolean</returnvalue>
11879 </para>
11880 <para>
11881 Is line vertical?
11882 </para>
11883 <para>
11884 <literal>?| lseg '[(-1,0),(1,0)]'</literal>
11885 <returnvalue>f</returnvalue>
11886 </para></entry>
11887 </row>
11889 <row>
11890 <entry role="func_table_entry"><para role="func_signature">
11891 <type>point</type> <literal>?|</literal> <type>point</type>
11892 <returnvalue>boolean</returnvalue>
11893 </para>
11894 <para>
11895 Are points vertically aligned (that is, have same x coordinate)?
11896 </para>
11897 <para>
11898 <literal>point '(0,1)' ?| point '(0,0)'</literal>
11899 <returnvalue>t</returnvalue>
11900 </para></entry>
11901 </row>
11903 <row>
11904 <entry role="func_table_entry"><para role="func_signature">
11905 <type>line</type> <literal>?-|</literal> <type>line</type>
11906 <returnvalue>boolean</returnvalue>
11907 </para>
11908 <para role="func_signature">
11909 <type>lseg</type> <literal>?-|</literal> <type>lseg</type>
11910 <returnvalue>boolean</returnvalue>
11911 </para>
11912 <para>
11913 Are lines perpendicular?
11914 </para>
11915 <para>
11916 <literal>lseg '[(0,0),(0,1)]' ?-| lseg '[(0,0),(1,0)]'</literal>
11917 <returnvalue>t</returnvalue>
11918 </para></entry>
11919 </row>
11921 <row>
11922 <entry role="func_table_entry"><para role="func_signature">
11923 <type>line</type> <literal>?||</literal> <type>line</type>
11924 <returnvalue>boolean</returnvalue>
11925 </para>
11926 <para role="func_signature">
11927 <type>lseg</type> <literal>?||</literal> <type>lseg</type>
11928 <returnvalue>boolean</returnvalue>
11929 </para>
11930 <para>
11931 Are lines parallel?
11932 </para>
11933 <para>
11934 <literal>lseg '[(-1,0),(1,0)]' ?|| lseg '[(-1,2),(1,2)]'</literal>
11935 <returnvalue>t</returnvalue>
11936 </para></entry>
11937 </row>
11939 <row>
11940 <entry role="func_table_entry"><para role="func_signature">
11941 <replaceable>geometric_type</replaceable> <literal>~=</literal> <replaceable>geometric_type</replaceable>
11942 <returnvalue>boolean</returnvalue>
11943 </para>
11944 <para>
11945 Are these objects the same?
11946 Available for <type>point</type>, <type>box</type>,
11947 <type>polygon</type>, <type>circle</type>.
11948 </para>
11949 <para>
11950 <literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal>
11951 <returnvalue>t</returnvalue>
11952 </para></entry>
11953 </row>
11954 </tbody>
11955 </tgroup>
11956 </table>
11958 <caution>
11959 <para>
11960 Note that the <quote>same as</quote> operator, <literal>~=</literal>,
11961 represents the usual notion of equality for the <type>point</type>,
11962 <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
11963 Some of the geometric types also have an <literal>=</literal> operator, but
11964 <literal>=</literal> compares for equal <emphasis>areas</emphasis> only.
11965 The other scalar comparison operators (<literal>&lt;=</literal> and so
11966 on), where available for these types, likewise compare areas.
11967 </para>
11968 </caution>
11970 <note>
11971 <para>
11972 Before <productname>PostgreSQL</productname> 14, the point
11973 is strictly below/above comparison operators <type>point</type>
11974 <literal>&lt;&lt;|</literal> <type>point</type> and <type>point</type>
11975 <literal>|&gt;&gt;</literal> <type>point</type> were respectively
11976 called <literal>&lt;^</literal> and <literal>&gt;^</literal>. These
11977 names are still available, but are deprecated and will eventually be
11978 removed.
11979 </para>
11980 </note>
11982 <table id="functions-geometry-func-table">
11983 <title>Geometric Functions</title>
11984 <tgroup cols="1">
11985 <thead>
11986 <row>
11987 <entry role="func_table_entry"><para role="func_signature">
11988 Function
11989 </para>
11990 <para>
11991 Description
11992 </para>
11993 <para>
11994 Example(s)
11995 </para></entry>
11996 </row>
11997 </thead>
11999 <tbody>
12000 <row>
12001 <entry role="func_table_entry"><para role="func_signature">
12002 <indexterm>
12003 <primary>area</primary>
12004 </indexterm>
12005 <function>area</function> ( <replaceable>geometric_type</replaceable> )
12006 <returnvalue>double precision</returnvalue>
12007 </para>
12008 <para>
12009 Computes area.
12010 Available for <type>box</type>, <type>path</type>, <type>circle</type>.
12011 A <type>path</type> input must be closed, else NULL is returned.
12012 Also, if the <type>path</type> is self-intersecting, the result may be
12013 meaningless.
12014 </para>
12015 <para>
12016 <literal>area(box '(2,2),(0,0)')</literal>
12017 <returnvalue>4</returnvalue>
12018 </para></entry>
12019 </row>
12021 <row>
12022 <entry role="func_table_entry"><para role="func_signature">
12023 <indexterm>
12024 <primary>center</primary>
12025 </indexterm>
12026 <function>center</function> ( <replaceable>geometric_type</replaceable> )
12027 <returnvalue>point</returnvalue>
12028 </para>
12029 <para>
12030 Computes center point.
12031 Available for <type>box</type>, <type>circle</type>.
12032 </para>
12033 <para>
12034 <literal>center(box '(1,2),(0,0)')</literal>
12035 <returnvalue>(0.5,1)</returnvalue>
12036 </para></entry>
12037 </row>
12039 <row>
12040 <entry role="func_table_entry"><para role="func_signature">
12041 <indexterm>
12042 <primary>diagonal</primary>
12043 </indexterm>
12044 <function>diagonal</function> ( <type>box</type> )
12045 <returnvalue>lseg</returnvalue>
12046 </para>
12047 <para>
12048 Extracts box's diagonal as a line segment
12049 (same as <function>lseg(box)</function>).
12050 </para>
12051 <para>
12052 <literal>diagonal(box '(1,2),(0,0)')</literal>
12053 <returnvalue>[(1,2),(0,0)]</returnvalue>
12054 </para></entry>
12055 </row>
12057 <row>
12058 <entry role="func_table_entry"><para role="func_signature">
12059 <indexterm>
12060 <primary>diameter</primary>
12061 </indexterm>
12062 <function>diameter</function> ( <type>circle</type> )
12063 <returnvalue>double precision</returnvalue>
12064 </para>
12065 <para>
12066 Computes diameter of circle.
12067 </para>
12068 <para>
12069 <literal>diameter(circle '&lt;(0,0),2&gt;')</literal>
12070 <returnvalue>4</returnvalue>
12071 </para></entry>
12072 </row>
12074 <row>
12075 <entry role="func_table_entry"><para role="func_signature">
12076 <indexterm>
12077 <primary>height</primary>
12078 </indexterm>
12079 <function>height</function> ( <type>box</type> )
12080 <returnvalue>double precision</returnvalue>
12081 </para>
12082 <para>
12083 Computes vertical size of box.
12084 </para>
12085 <para>
12086 <literal>height(box '(1,2),(0,0)')</literal>
12087 <returnvalue>2</returnvalue>
12088 </para></entry>
12089 </row>
12091 <row>
12092 <entry role="func_table_entry"><para role="func_signature">
12093 <indexterm>
12094 <primary>isclosed</primary>
12095 </indexterm>
12096 <function>isclosed</function> ( <type>path</type> )
12097 <returnvalue>boolean</returnvalue>
12098 </para>
12099 <para>
12100 Is path closed?
12101 </para>
12102 <para>
12103 <literal>isclosed(path '((0,0),(1,1),(2,0))')</literal>
12104 <returnvalue>t</returnvalue>
12105 </para></entry>
12106 </row>
12108 <row>
12109 <entry role="func_table_entry"><para role="func_signature">
12110 <indexterm>
12111 <primary>isopen</primary>
12112 </indexterm>
12113 <function>isopen</function> ( <type>path</type> )
12114 <returnvalue>boolean</returnvalue>
12115 </para>
12116 <para>
12117 Is path open?
12118 </para>
12119 <para>
12120 <literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal>
12121 <returnvalue>t</returnvalue>
12122 </para></entry>
12123 </row>
12125 <row>
12126 <entry role="func_table_entry"><para role="func_signature">
12127 <indexterm>
12128 <primary>length</primary>
12129 </indexterm>
12130 <function>length</function> ( <replaceable>geometric_type</replaceable> )
12131 <returnvalue>double precision</returnvalue>
12132 </para>
12133 <para>
12134 Computes the total length.
12135 Available for <type>lseg</type>, <type>path</type>.
12136 </para>
12137 <para>
12138 <literal>length(path '((-1,0),(1,0))')</literal>
12139 <returnvalue>4</returnvalue>
12140 </para></entry>
12141 </row>
12143 <row>
12144 <entry role="func_table_entry"><para role="func_signature">
12145 <indexterm>
12146 <primary>npoints</primary>
12147 </indexterm>
12148 <function>npoints</function> ( <replaceable>geometric_type</replaceable> )
12149 <returnvalue>integer</returnvalue>
12150 </para>
12151 <para>
12152 Returns the number of points.
12153 Available for <type>path</type>, <type>polygon</type>.
12154 </para>
12155 <para>
12156 <literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal>
12157 <returnvalue>3</returnvalue>
12158 </para></entry>
12159 </row>
12161 <row>
12162 <entry role="func_table_entry"><para role="func_signature">
12163 <indexterm>
12164 <primary>pclose</primary>
12165 </indexterm>
12166 <function>pclose</function> ( <type>path</type> )
12167 <returnvalue>path</returnvalue>
12168 </para>
12169 <para>
12170 Converts path to closed form.
12171 </para>
12172 <para>
12173 <literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal>
12174 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12175 </para></entry>
12176 </row>
12178 <row>
12179 <entry role="func_table_entry"><para role="func_signature">
12180 <indexterm>
12181 <primary>popen</primary>
12182 </indexterm>
12183 <function>popen</function> ( <type>path</type> )
12184 <returnvalue>path</returnvalue>
12185 </para>
12186 <para>
12187 Converts path to open form.
12188 </para>
12189 <para>
12190 <literal>popen(path '((0,0),(1,1),(2,0))')</literal>
12191 <returnvalue>[(0,0),(1,1),(2,0)]</returnvalue>
12192 </para></entry>
12193 </row>
12195 <row>
12196 <entry role="func_table_entry"><para role="func_signature">
12197 <indexterm>
12198 <primary>radius</primary>
12199 </indexterm>
12200 <function>radius</function> ( <type>circle</type> )
12201 <returnvalue>double precision</returnvalue>
12202 </para>
12203 <para>
12204 Computes radius of circle.
12205 </para>
12206 <para>
12207 <literal>radius(circle '&lt;(0,0),2&gt;')</literal>
12208 <returnvalue>2</returnvalue>
12209 </para></entry>
12210 </row>
12212 <row>
12213 <entry role="func_table_entry"><para role="func_signature">
12214 <indexterm>
12215 <primary>slope</primary>
12216 </indexterm>
12217 <function>slope</function> ( <type>point</type>, <type>point</type> )
12218 <returnvalue>double precision</returnvalue>
12219 </para>
12220 <para>
12221 Computes slope of a line drawn through the two points.
12222 </para>
12223 <para>
12224 <literal>slope(point '(0,0)', point '(2,1)')</literal>
12225 <returnvalue>0.5</returnvalue>
12226 </para></entry>
12227 </row>
12229 <row>
12230 <entry role="func_table_entry"><para role="func_signature">
12231 <indexterm>
12232 <primary>width</primary>
12233 </indexterm>
12234 <function>width</function> ( <type>box</type> )
12235 <returnvalue>double precision</returnvalue>
12236 </para>
12237 <para>
12238 Computes horizontal size of box.
12239 </para>
12240 <para>
12241 <literal>width(box '(1,2),(0,0)')</literal>
12242 <returnvalue>1</returnvalue>
12243 </para></entry>
12244 </row>
12245 </tbody>
12246 </tgroup>
12247 </table>
12249 <table id="functions-geometry-conv-table">
12250 <title>Geometric Type Conversion Functions</title>
12251 <tgroup cols="1">
12252 <thead>
12253 <row>
12254 <entry role="func_table_entry"><para role="func_signature">
12255 Function
12256 </para>
12257 <para>
12258 Description
12259 </para>
12260 <para>
12261 Example(s)
12262 </para></entry>
12263 </row>
12264 </thead>
12265 <tbody>
12267 <row>
12268 <entry role="func_table_entry"><para role="func_signature">
12269 <indexterm>
12270 <primary>box</primary>
12271 </indexterm>
12272 <function>box</function> ( <type>circle</type> )
12273 <returnvalue>box</returnvalue>
12274 </para>
12275 <para>
12276 Computes box inscribed within the circle.
12277 </para>
12278 <para>
12279 <literal>box(circle '&lt;(0,0),2&gt;')</literal>
12280 <returnvalue>(1.414213562373095,1.414213562373095),&zwsp;(-1.414213562373095,-1.414213562373095)</returnvalue>
12281 </para></entry>
12282 </row>
12284 <row>
12285 <entry role="func_table_entry"><para role="func_signature">
12286 <function>box</function> ( <type>point</type> )
12287 <returnvalue>box</returnvalue>
12288 </para>
12289 <para>
12290 Converts point to empty box.
12291 </para>
12292 <para>
12293 <literal>box(point '(1,0)')</literal>
12294 <returnvalue>(1,0),(1,0)</returnvalue>
12295 </para></entry>
12296 </row>
12298 <row>
12299 <entry role="func_table_entry"><para role="func_signature">
12300 <function>box</function> ( <type>point</type>, <type>point</type> )
12301 <returnvalue>box</returnvalue>
12302 </para>
12303 <para>
12304 Converts any two corner points to box.
12305 </para>
12306 <para>
12307 <literal>box(point '(0,1)', point '(1,0)')</literal>
12308 <returnvalue>(1,1),(0,0)</returnvalue>
12309 </para></entry>
12310 </row>
12312 <row>
12313 <entry role="func_table_entry"><para role="func_signature">
12314 <function>box</function> ( <type>polygon</type> )
12315 <returnvalue>box</returnvalue>
12316 </para>
12317 <para>
12318 Computes bounding box of polygon.
12319 </para>
12320 <para>
12321 <literal>box(polygon '((0,0),(1,1),(2,0))')</literal>
12322 <returnvalue>(2,1),(0,0)</returnvalue>
12323 </para></entry>
12324 </row>
12326 <row>
12327 <entry role="func_table_entry"><para role="func_signature">
12328 <indexterm>
12329 <primary>bound_box</primary>
12330 </indexterm>
12331 <function>bound_box</function> ( <type>box</type>, <type>box</type> )
12332 <returnvalue>box</returnvalue>
12333 </para>
12334 <para>
12335 Computes bounding box of two boxes.
12336 </para>
12337 <para>
12338 <literal>bound_box(box '(1,1),(0,0)', box '(4,4),(3,3)')</literal>
12339 <returnvalue>(4,4),(0,0)</returnvalue>
12340 </para></entry>
12341 </row>
12343 <row>
12344 <entry role="func_table_entry"><para role="func_signature">
12345 <indexterm>
12346 <primary>circle</primary>
12347 </indexterm>
12348 <function>circle</function> ( <type>box</type> )
12349 <returnvalue>circle</returnvalue>
12350 </para>
12351 <para>
12352 Computes smallest circle enclosing box.
12353 </para>
12354 <para>
12355 <literal>circle(box '(1,1),(0,0)')</literal>
12356 <returnvalue>&lt;(0.5,0.5),0.7071067811865476&gt;</returnvalue>
12357 </para></entry>
12358 </row>
12360 <row>
12361 <entry role="func_table_entry"><para role="func_signature">
12362 <function>circle</function> ( <type>point</type>, <type>double precision</type> )
12363 <returnvalue>circle</returnvalue>
12364 </para>
12365 <para>
12366 Constructs circle from center and radius.
12367 </para>
12368 <para>
12369 <literal>circle(point '(0,0)', 2.0)</literal>
12370 <returnvalue>&lt;(0,0),2&gt;</returnvalue>
12371 </para></entry>
12372 </row>
12374 <row>
12375 <entry role="func_table_entry"><para role="func_signature">
12376 <function>circle</function> ( <type>polygon</type> )
12377 <returnvalue>circle</returnvalue>
12378 </para>
12379 <para>
12380 Converts polygon to circle. The circle's center is the mean of the
12381 positions of the polygon's points, and the radius is the average
12382 distance of the polygon's points from that center.
12383 </para>
12384 <para>
12385 <literal>circle(polygon '((0,0),(1,3),(2,0))')</literal>
12386 <returnvalue>&lt;(1,1),1.6094757082487299&gt;</returnvalue>
12387 </para></entry>
12388 </row>
12390 <row>
12391 <entry role="func_table_entry"><para role="func_signature">
12392 <indexterm>
12393 <primary>line</primary>
12394 </indexterm>
12395 <function>line</function> ( <type>point</type>, <type>point</type> )
12396 <returnvalue>line</returnvalue>
12397 </para>
12398 <para>
12399 Converts two points to the line through them.
12400 </para>
12401 <para>
12402 <literal>line(point '(-1,0)', point '(1,0)')</literal>
12403 <returnvalue>{0,-1,0}</returnvalue>
12404 </para></entry>
12405 </row>
12407 <row>
12408 <entry role="func_table_entry"><para role="func_signature">
12409 <indexterm>
12410 <primary>lseg</primary>
12411 </indexterm>
12412 <function>lseg</function> ( <type>box</type> )
12413 <returnvalue>lseg</returnvalue>
12414 </para>
12415 <para>
12416 Extracts box's diagonal as a line segment.
12417 </para>
12418 <para>
12419 <literal>lseg(box '(1,0),(-1,0)')</literal>
12420 <returnvalue>[(1,0),(-1,0)]</returnvalue>
12421 </para></entry>
12422 </row>
12424 <row>
12425 <entry role="func_table_entry"><para role="func_signature">
12426 <function>lseg</function> ( <type>point</type>, <type>point</type> )
12427 <returnvalue>lseg</returnvalue>
12428 </para>
12429 <para>
12430 Constructs line segment from two endpoints.
12431 </para>
12432 <para>
12433 <literal>lseg(point '(-1,0)', point '(1,0)')</literal>
12434 <returnvalue>[(-1,0),(1,0)]</returnvalue>
12435 </para></entry>
12436 </row>
12438 <row>
12439 <entry role="func_table_entry"><para role="func_signature">
12440 <indexterm>
12441 <primary>path</primary>
12442 </indexterm>
12443 <function>path</function> ( <type>polygon</type> )
12444 <returnvalue>path</returnvalue>
12445 </para>
12446 <para>
12447 Converts polygon to a closed path with the same list of points.
12448 </para>
12449 <para>
12450 <literal>path(polygon '((0,0),(1,1),(2,0))')</literal>
12451 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12452 </para></entry>
12453 </row>
12455 <row>
12456 <entry role="func_table_entry"><para role="func_signature">
12457 <indexterm>
12458 <primary>point</primary>
12459 </indexterm>
12460 <function>point</function> ( <type>double precision</type>, <type>double precision</type> )
12461 <returnvalue>point</returnvalue>
12462 </para>
12463 <para>
12464 Constructs point from its coordinates.
12465 </para>
12466 <para>
12467 <literal>point(23.4, -44.5)</literal>
12468 <returnvalue>(23.4,-44.5)</returnvalue>
12469 </para></entry>
12470 </row>
12472 <row>
12473 <entry role="func_table_entry"><para role="func_signature">
12474 <function>point</function> ( <type>box</type> )
12475 <returnvalue>point</returnvalue>
12476 </para>
12477 <para>
12478 Computes center of box.
12479 </para>
12480 <para>
12481 <literal>point(box '(1,0),(-1,0)')</literal>
12482 <returnvalue>(0,0)</returnvalue>
12483 </para></entry>
12484 </row>
12486 <row>
12487 <entry role="func_table_entry"><para role="func_signature">
12488 <function>point</function> ( <type>circle</type> )
12489 <returnvalue>point</returnvalue>
12490 </para>
12491 <para>
12492 Computes center of circle.
12493 </para>
12494 <para>
12495 <literal>point(circle '&lt;(0,0),2&gt;')</literal>
12496 <returnvalue>(0,0)</returnvalue>
12497 </para></entry>
12498 </row>
12500 <row>
12501 <entry role="func_table_entry"><para role="func_signature">
12502 <function>point</function> ( <type>lseg</type> )
12503 <returnvalue>point</returnvalue>
12504 </para>
12505 <para>
12506 Computes center of line segment.
12507 </para>
12508 <para>
12509 <literal>point(lseg '[(-1,0),(1,0)]')</literal>
12510 <returnvalue>(0,0)</returnvalue>
12511 </para></entry>
12512 </row>
12514 <row>
12515 <entry role="func_table_entry"><para role="func_signature">
12516 <function>point</function> ( <type>polygon</type> )
12517 <returnvalue>point</returnvalue>
12518 </para>
12519 <para>
12520 Computes center of polygon (the mean of the
12521 positions of the polygon's points).
12522 </para>
12523 <para>
12524 <literal>point(polygon '((0,0),(1,1),(2,0))')</literal>
12525 <returnvalue>(1,0.3333333333333333)</returnvalue>
12526 </para></entry>
12527 </row>
12529 <row>
12530 <entry role="func_table_entry"><para role="func_signature">
12531 <indexterm>
12532 <primary>polygon</primary>
12533 </indexterm>
12534 <function>polygon</function> ( <type>box</type> )
12535 <returnvalue>polygon</returnvalue>
12536 </para>
12537 <para>
12538 Converts box to a 4-point polygon.
12539 </para>
12540 <para>
12541 <literal>polygon(box '(1,1),(0,0)')</literal>
12542 <returnvalue>((0,0),(0,1),(1,1),(1,0))</returnvalue>
12543 </para></entry>
12544 </row>
12546 <row>
12547 <entry role="func_table_entry"><para role="func_signature">
12548 <function>polygon</function> ( <type>circle</type> )
12549 <returnvalue>polygon</returnvalue>
12550 </para>
12551 <para>
12552 Converts circle to a 12-point polygon.
12553 </para>
12554 <para>
12555 <literal>polygon(circle '&lt;(0,0),2&gt;')</literal>
12556 <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>
12557 </para></entry>
12558 </row>
12560 <row>
12561 <entry role="func_table_entry"><para role="func_signature">
12562 <function>polygon</function> ( <type>integer</type>, <type>circle</type> )
12563 <returnvalue>polygon</returnvalue>
12564 </para>
12565 <para>
12566 Converts circle to an <replaceable>n</replaceable>-point polygon.
12567 </para>
12568 <para>
12569 <literal>polygon(4, circle '&lt;(3,0),1&gt;')</literal>
12570 <returnvalue>((2,0),&zwsp;(3,1),&zwsp;(4,1.2246063538223773e-16),&zwsp;(3,-1))</returnvalue>
12571 </para></entry>
12572 </row>
12574 <row>
12575 <entry role="func_table_entry"><para role="func_signature">
12576 <function>polygon</function> ( <type>path</type> )
12577 <returnvalue>polygon</returnvalue>
12578 </para>
12579 <para>
12580 Converts closed path to a polygon with the same list of points.
12581 </para>
12582 <para>
12583 <literal>polygon(path '((0,0),(1,1),(2,0))')</literal>
12584 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12585 </para></entry>
12586 </row>
12588 </tbody>
12589 </tgroup>
12590 </table>
12592 <para>
12593 It is possible to access the two component numbers of a <type>point</type>
12594 as though the point were an array with indexes 0 and 1. For example, if
12595 <literal>t.p</literal> is a <type>point</type> column then
12596 <literal>SELECT p[0] FROM t</literal> retrieves the X coordinate and
12597 <literal>UPDATE t SET p[1] = ...</literal> changes the Y coordinate.
12598 In the same way, a value of type <type>box</type> or <type>lseg</type> can be treated
12599 as an array of two <type>point</type> values.
12600 </para>
12602 </sect1>
12605 <sect1 id="functions-net">
12606 <title>Network Address Functions and Operators</title>
12608 <para>
12609 The IP network address types, <type>cidr</type> and <type>inet</type>,
12610 support the usual comparison operators shown in
12611 <xref linkend="functions-comparison-op-table"/>
12612 as well as the specialized operators and functions shown in
12613 <xref linkend="cidr-inet-operators-table"/> and
12614 <xref linkend="cidr-inet-functions-table"/>.
12615 </para>
12617 <para>
12618 Any <type>cidr</type> value can be cast to <type>inet</type> implicitly;
12619 therefore, the operators and functions shown below as operating on
12620 <type>inet</type> also work on <type>cidr</type> values. (Where there are
12621 separate functions for <type>inet</type> and <type>cidr</type>, it is
12622 because the behavior should be different for the two cases.)
12623 Also, it is permitted to cast an <type>inet</type> value
12624 to <type>cidr</type>. When this is done, any bits to the right of the
12625 netmask are silently zeroed to create a valid <type>cidr</type> value.
12626 </para>
12628 <table id="cidr-inet-operators-table">
12629 <title>IP Address Operators</title>
12630 <tgroup cols="1">
12631 <thead>
12632 <row>
12633 <entry role="func_table_entry"><para role="func_signature">
12634 Operator
12635 </para>
12636 <para>
12637 Description
12638 </para>
12639 <para>
12640 Example(s)
12641 </para></entry>
12642 </row>
12643 </thead>
12645 <tbody>
12646 <row>
12647 <entry role="func_table_entry"><para role="func_signature">
12648 <type>inet</type> <literal>&lt;&lt;</literal> <type>inet</type>
12649 <returnvalue>boolean</returnvalue>
12650 </para>
12651 <para>
12652 Is subnet strictly contained by subnet?
12653 This operator, and the next four, test for subnet inclusion. They
12654 consider only the network parts of the two addresses (ignoring any
12655 bits to the right of the netmasks) and determine whether one network
12656 is identical to or a subnet of the other.
12657 </para>
12658 <para>
12659 <literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal>
12660 <returnvalue>t</returnvalue>
12661 </para>
12662 <para>
12663 <literal>inet '192.168.0.5' &lt;&lt; inet '192.168.1/24'</literal>
12664 <returnvalue>f</returnvalue>
12665 </para>
12666 <para>
12667 <literal>inet '192.168.1/24' &lt;&lt; inet '192.168.1/24'</literal>
12668 <returnvalue>f</returnvalue>
12669 </para></entry>
12670 </row>
12672 <row>
12673 <entry role="func_table_entry"><para role="func_signature">
12674 <type>inet</type> <literal>&lt;&lt;=</literal> <type>inet</type>
12675 <returnvalue>boolean</returnvalue>
12676 </para>
12677 <para>
12678 Is subnet contained by or equal to subnet?
12679 </para>
12680 <para>
12681 <literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal>
12682 <returnvalue>t</returnvalue>
12683 </para></entry>
12684 </row>
12686 <row>
12687 <entry role="func_table_entry"><para role="func_signature">
12688 <type>inet</type> <literal>&gt;&gt;</literal> <type>inet</type>
12689 <returnvalue>boolean</returnvalue>
12690 </para>
12691 <para>
12692 Does subnet strictly contain subnet?
12693 </para>
12694 <para>
12695 <literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal>
12696 <returnvalue>t</returnvalue>
12697 </para></entry>
12698 </row>
12700 <row>
12701 <entry role="func_table_entry"><para role="func_signature">
12702 <type>inet</type> <literal>&gt;&gt;=</literal> <type>inet</type>
12703 <returnvalue>boolean</returnvalue>
12704 </para>
12705 <para>
12706 Does subnet contain or equal subnet?
12707 </para>
12708 <para>
12709 <literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal>
12710 <returnvalue>t</returnvalue>
12711 </para></entry>
12712 </row>
12714 <row>
12715 <entry role="func_table_entry"><para role="func_signature">
12716 <type>inet</type> <literal>&amp;&amp;</literal> <type>inet</type>
12717 <returnvalue>boolean</returnvalue>
12718 </para>
12719 <para>
12720 Does either subnet contain or equal the other?
12721 </para>
12722 <para>
12723 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.1.80/28'</literal>
12724 <returnvalue>t</returnvalue>
12725 </para>
12726 <para>
12727 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.2.0/28'</literal>
12728 <returnvalue>f</returnvalue>
12729 </para></entry>
12730 </row>
12732 <row>
12733 <entry role="func_table_entry"><para role="func_signature">
12734 <literal>~</literal> <type>inet</type>
12735 <returnvalue>inet</returnvalue>
12736 </para>
12737 <para>
12738 Computes bitwise NOT.
12739 </para>
12740 <para>
12741 <literal>~ inet '192.168.1.6'</literal>
12742 <returnvalue>63.87.254.249</returnvalue>
12743 </para></entry>
12744 </row>
12746 <row>
12747 <entry role="func_table_entry"><para role="func_signature">
12748 <type>inet</type> <literal>&amp;</literal> <type>inet</type>
12749 <returnvalue>inet</returnvalue>
12750 </para>
12751 <para>
12752 Computes bitwise AND.
12753 </para>
12754 <para>
12755 <literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal>
12756 <returnvalue>0.0.0.6</returnvalue>
12757 </para></entry>
12758 </row>
12760 <row>
12761 <entry role="func_table_entry"><para role="func_signature">
12762 <type>inet</type> <literal>|</literal> <type>inet</type>
12763 <returnvalue>inet</returnvalue>
12764 </para>
12765 <para>
12766 Computes bitwise OR.
12767 </para>
12768 <para>
12769 <literal>inet '192.168.1.6' | inet '0.0.0.255'</literal>
12770 <returnvalue>192.168.1.255</returnvalue>
12771 </para></entry>
12772 </row>
12774 <row>
12775 <entry role="func_table_entry"><para role="func_signature">
12776 <type>inet</type> <literal>+</literal> <type>bigint</type>
12777 <returnvalue>inet</returnvalue>
12778 </para>
12779 <para>
12780 Adds an offset to an address.
12781 </para>
12782 <para>
12783 <literal>inet '192.168.1.6' + 25</literal>
12784 <returnvalue>192.168.1.31</returnvalue>
12785 </para></entry>
12786 </row>
12788 <row>
12789 <entry role="func_table_entry"><para role="func_signature">
12790 <type>bigint</type> <literal>+</literal> <type>inet</type>
12791 <returnvalue>inet</returnvalue>
12792 </para>
12793 <para>
12794 Adds an offset to an address.
12795 </para>
12796 <para>
12797 <literal>200 + inet '::ffff:fff0:1'</literal>
12798 <returnvalue>::ffff:255.240.0.201</returnvalue>
12799 </para></entry>
12800 </row>
12802 <row>
12803 <entry role="func_table_entry"><para role="func_signature">
12804 <type>inet</type> <literal>-</literal> <type>bigint</type>
12805 <returnvalue>inet</returnvalue>
12806 </para>
12807 <para>
12808 Subtracts an offset from an address.
12809 </para>
12810 <para>
12811 <literal>inet '192.168.1.43' - 36</literal>
12812 <returnvalue>192.168.1.7</returnvalue>
12813 </para></entry>
12814 </row>
12816 <row>
12817 <entry role="func_table_entry"><para role="func_signature">
12818 <type>inet</type> <literal>-</literal> <type>inet</type>
12819 <returnvalue>bigint</returnvalue>
12820 </para>
12821 <para>
12822 Computes the difference of two addresses.
12823 </para>
12824 <para>
12825 <literal>inet '192.168.1.43' - inet '192.168.1.19'</literal>
12826 <returnvalue>24</returnvalue>
12827 </para>
12828 <para>
12829 <literal>inet '::1' - inet '::ffff:1'</literal>
12830 <returnvalue>-4294901760</returnvalue>
12831 </para></entry>
12832 </row>
12833 </tbody>
12834 </tgroup>
12835 </table>
12837 <table id="cidr-inet-functions-table">
12838 <title>IP Address Functions</title>
12839 <tgroup cols="1">
12840 <thead>
12841 <row>
12842 <entry role="func_table_entry"><para role="func_signature">
12843 Function
12844 </para>
12845 <para>
12846 Description
12847 </para>
12848 <para>
12849 Example(s)
12850 </para></entry>
12851 </row>
12852 </thead>
12854 <tbody>
12855 <row>
12856 <entry role="func_table_entry"><para role="func_signature">
12857 <indexterm>
12858 <primary>abbrev</primary>
12859 </indexterm>
12860 <function>abbrev</function> ( <type>inet</type> )
12861 <returnvalue>text</returnvalue>
12862 </para>
12863 <para>
12864 Creates an abbreviated display format as text.
12865 (The result is the same as the <type>inet</type> output function
12866 produces; it is <quote>abbreviated</quote> only in comparison to the
12867 result of an explicit cast to <type>text</type>, which for historical
12868 reasons will never suppress the netmask part.)
12869 </para>
12870 <para>
12871 <literal>abbrev(inet '10.1.0.0/32')</literal>
12872 <returnvalue>10.1.0.0</returnvalue>
12873 </para></entry>
12874 </row>
12876 <row>
12877 <entry role="func_table_entry"><para role="func_signature">
12878 <function>abbrev</function> ( <type>cidr</type> )
12879 <returnvalue>text</returnvalue>
12880 </para>
12881 <para>
12882 Creates an abbreviated display format as text.
12883 (The abbreviation consists of dropping all-zero octets to the right
12884 of the netmask; more examples are in
12885 <xref linkend="datatype-net-cidr-table"/>.)
12886 </para>
12887 <para>
12888 <literal>abbrev(cidr '10.1.0.0/16')</literal>
12889 <returnvalue>10.1/16</returnvalue>
12890 </para></entry>
12891 </row>
12893 <row>
12894 <entry role="func_table_entry"><para role="func_signature">
12895 <indexterm>
12896 <primary>broadcast</primary>
12897 </indexterm>
12898 <function>broadcast</function> ( <type>inet</type> )
12899 <returnvalue>inet</returnvalue>
12900 </para>
12901 <para>
12902 Computes the broadcast address for the address's network.
12903 </para>
12904 <para>
12905 <literal>broadcast(inet '192.168.1.5/24')</literal>
12906 <returnvalue>192.168.1.255/24</returnvalue>
12907 </para></entry>
12908 </row>
12910 <row>
12911 <entry role="func_table_entry"><para role="func_signature">
12912 <indexterm>
12913 <primary>family</primary>
12914 </indexterm>
12915 <function>family</function> ( <type>inet</type> )
12916 <returnvalue>integer</returnvalue>
12917 </para>
12918 <para>
12919 Returns the address's family: <literal>4</literal> for IPv4,
12920 <literal>6</literal> for IPv6.
12921 </para>
12922 <para>
12923 <literal>family(inet '::1')</literal>
12924 <returnvalue>6</returnvalue>
12925 </para></entry>
12926 </row>
12928 <row>
12929 <entry role="func_table_entry"><para role="func_signature">
12930 <indexterm>
12931 <primary>host</primary>
12932 </indexterm>
12933 <function>host</function> ( <type>inet</type> )
12934 <returnvalue>text</returnvalue>
12935 </para>
12936 <para>
12937 Returns the IP address as text, ignoring the netmask.
12938 </para>
12939 <para>
12940 <literal>host(inet '192.168.1.0/24')</literal>
12941 <returnvalue>192.168.1.0</returnvalue>
12942 </para></entry>
12943 </row>
12945 <row>
12946 <entry role="func_table_entry"><para role="func_signature">
12947 <indexterm>
12948 <primary>hostmask</primary>
12949 </indexterm>
12950 <function>hostmask</function> ( <type>inet</type> )
12951 <returnvalue>inet</returnvalue>
12952 </para>
12953 <para>
12954 Computes the host mask for the address's network.
12955 </para>
12956 <para>
12957 <literal>hostmask(inet '192.168.23.20/30')</literal>
12958 <returnvalue>0.0.0.3</returnvalue>
12959 </para></entry>
12960 </row>
12962 <row>
12963 <entry role="func_table_entry"><para role="func_signature">
12964 <indexterm>
12965 <primary>inet_merge</primary>
12966 </indexterm>
12967 <function>inet_merge</function> ( <type>inet</type>, <type>inet</type> )
12968 <returnvalue>cidr</returnvalue>
12969 </para>
12970 <para>
12971 Computes the smallest network that includes both of the given networks.
12972 </para>
12973 <para>
12974 <literal>inet_merge(inet '192.168.1.5/24', inet '192.168.2.5/24')</literal>
12975 <returnvalue>192.168.0.0/22</returnvalue>
12976 </para></entry>
12977 </row>
12979 <row>
12980 <entry role="func_table_entry"><para role="func_signature">
12981 <indexterm>
12982 <primary>inet_same_family</primary>
12983 </indexterm>
12984 <function>inet_same_family</function> ( <type>inet</type>, <type>inet</type> )
12985 <returnvalue>boolean</returnvalue>
12986 </para>
12987 <para>
12988 Tests whether the addresses belong to the same IP family.
12989 </para>
12990 <para>
12991 <literal>inet_same_family(inet '192.168.1.5/24', inet '::1')</literal>
12992 <returnvalue>f</returnvalue>
12993 </para></entry>
12994 </row>
12996 <row>
12997 <entry role="func_table_entry"><para role="func_signature">
12998 <indexterm>
12999 <primary>masklen</primary>
13000 </indexterm>
13001 <function>masklen</function> ( <type>inet</type> )
13002 <returnvalue>integer</returnvalue>
13003 </para>
13004 <para>
13005 Returns the netmask length in bits.
13006 </para>
13007 <para>
13008 <literal>masklen(inet '192.168.1.5/24')</literal>
13009 <returnvalue>24</returnvalue>
13010 </para></entry>
13011 </row>
13013 <row>
13014 <entry role="func_table_entry"><para role="func_signature">
13015 <indexterm>
13016 <primary>netmask</primary>
13017 </indexterm>
13018 <function>netmask</function> ( <type>inet</type> )
13019 <returnvalue>inet</returnvalue>
13020 </para>
13021 <para>
13022 Computes the network mask for the address's network.
13023 </para>
13024 <para>
13025 <literal>netmask(inet '192.168.1.5/24')</literal>
13026 <returnvalue>255.255.255.0</returnvalue>
13027 </para></entry>
13028 </row>
13030 <row>
13031 <entry role="func_table_entry"><para role="func_signature">
13032 <indexterm>
13033 <primary>network</primary>
13034 </indexterm>
13035 <function>network</function> ( <type>inet</type> )
13036 <returnvalue>cidr</returnvalue>
13037 </para>
13038 <para>
13039 Returns the network part of the address, zeroing out
13040 whatever is to the right of the netmask.
13041 (This is equivalent to casting the value to <type>cidr</type>.)
13042 </para>
13043 <para>
13044 <literal>network(inet '192.168.1.5/24')</literal>
13045 <returnvalue>192.168.1.0/24</returnvalue>
13046 </para></entry>
13047 </row>
13049 <row>
13050 <entry role="func_table_entry"><para role="func_signature">
13051 <indexterm>
13052 <primary>set_masklen</primary>
13053 </indexterm>
13054 <function>set_masklen</function> ( <type>inet</type>, <type>integer</type> )
13055 <returnvalue>inet</returnvalue>
13056 </para>
13057 <para>
13058 Sets the netmask length for an <type>inet</type> value.
13059 The address part does not change.
13060 </para>
13061 <para>
13062 <literal>set_masklen(inet '192.168.1.5/24', 16)</literal>
13063 <returnvalue>192.168.1.5/16</returnvalue>
13064 </para></entry>
13065 </row>
13067 <row>
13068 <entry role="func_table_entry"><para role="func_signature">
13069 <function>set_masklen</function> ( <type>cidr</type>, <type>integer</type> )
13070 <returnvalue>cidr</returnvalue>
13071 </para>
13072 <para>
13073 Sets the netmask length for a <type>cidr</type> value.
13074 Address bits to the right of the new netmask are set to zero.
13075 </para>
13076 <para>
13077 <literal>set_masklen(cidr '192.168.1.0/24', 16)</literal>
13078 <returnvalue>192.168.0.0/16</returnvalue>
13079 </para></entry>
13080 </row>
13082 <row>
13083 <entry role="func_table_entry"><para role="func_signature">
13084 <indexterm>
13085 <primary>text</primary>
13086 </indexterm>
13087 <function>text</function> ( <type>inet</type> )
13088 <returnvalue>text</returnvalue>
13089 </para>
13090 <para>
13091 Returns the unabbreviated IP address and netmask length as text.
13092 (This has the same result as an explicit cast to <type>text</type>.)
13093 </para>
13094 <para>
13095 <literal>text(inet '192.168.1.5')</literal>
13096 <returnvalue>192.168.1.5/32</returnvalue>
13097 </para></entry>
13098 </row>
13099 </tbody>
13100 </tgroup>
13101 </table>
13103 <tip>
13104 <para>
13105 The <function>abbrev</function>, <function>host</function>,
13106 and <function>text</function> functions are primarily intended to offer
13107 alternative display formats for IP addresses.
13108 </para>
13109 </tip>
13111 <para>
13112 The MAC address types, <type>macaddr</type> and <type>macaddr8</type>,
13113 support the usual comparison operators shown in
13114 <xref linkend="functions-comparison-op-table"/>
13115 as well as the specialized functions shown in
13116 <xref linkend="macaddr-functions-table"/>.
13117 In addition, they support the bitwise logical operators
13118 <literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>
13119 (NOT, AND and OR), just as shown above for IP addresses.
13120 </para>
13122 <table id="macaddr-functions-table">
13123 <title>MAC Address Functions</title>
13124 <tgroup cols="1">
13125 <thead>
13126 <row>
13127 <entry role="func_table_entry"><para role="func_signature">
13128 Function
13129 </para>
13130 <para>
13131 Description
13132 </para>
13133 <para>
13134 Example(s)
13135 </para></entry>
13136 </row>
13137 </thead>
13139 <tbody>
13140 <row>
13141 <entry role="func_table_entry"><para role="func_signature">
13142 <indexterm>
13143 <primary>trunc</primary>
13144 </indexterm>
13145 <function>trunc</function> ( <type>macaddr</type> )
13146 <returnvalue>macaddr</returnvalue>
13147 </para>
13148 <para>
13149 Sets the last 3 bytes of the address to zero. The remaining prefix
13150 can be associated with a particular manufacturer (using data not
13151 included in <productname>PostgreSQL</productname>).
13152 </para>
13153 <para>
13154 <literal>trunc(macaddr '12:34:56:78:90:ab')</literal>
13155 <returnvalue>12:34:56:00:00:00</returnvalue>
13156 </para></entry>
13157 </row>
13159 <row>
13160 <entry role="func_table_entry"><para role="func_signature">
13161 <function>trunc</function> ( <type>macaddr8</type> )
13162 <returnvalue>macaddr8</returnvalue>
13163 </para>
13164 <para>
13165 Sets the last 5 bytes of the address to zero. The remaining prefix
13166 can be associated with a particular manufacturer (using data not
13167 included in <productname>PostgreSQL</productname>).
13168 </para>
13169 <para>
13170 <literal>trunc(macaddr8 '12:34:56:78:90:ab:cd:ef')</literal>
13171 <returnvalue>12:34:56:00:00:00:00:00</returnvalue>
13172 </para></entry>
13173 </row>
13175 <row>
13176 <entry role="func_table_entry"><para role="func_signature">
13177 <indexterm>
13178 <primary>macaddr8_set7bit</primary>
13179 </indexterm>
13180 <function>macaddr8_set7bit</function> ( <type>macaddr8</type> )
13181 <returnvalue>macaddr8</returnvalue>
13182 </para>
13183 <para>
13184 Sets the 7th bit of the address to one, creating what is known as
13185 modified EUI-64, for inclusion in an IPv6 address.
13186 </para>
13187 <para>
13188 <literal>macaddr8_set7bit(macaddr8 '00:34:56:ab:cd:ef')</literal>
13189 <returnvalue>02:34:56:ff:fe:ab:cd:ef</returnvalue>
13190 </para></entry>
13191 </row>
13192 </tbody>
13193 </tgroup>
13194 </table>
13196 </sect1>
13199 <sect1 id="functions-textsearch">
13200 <title>Text Search Functions and Operators</title>
13202 <indexterm zone="datatype-textsearch">
13203 <primary>full text search</primary>
13204 <secondary>functions and operators</secondary>
13205 </indexterm>
13207 <indexterm zone="datatype-textsearch">
13208 <primary>text search</primary>
13209 <secondary>functions and operators</secondary>
13210 </indexterm>
13212 <para>
13213 <xref linkend="textsearch-operators-table"/>,
13214 <xref linkend="textsearch-functions-table"/> and
13215 <xref linkend="textsearch-functions-debug-table"/>
13216 summarize the functions and operators that are provided
13217 for full text searching. See <xref linkend="textsearch"/> for a detailed
13218 explanation of <productname>PostgreSQL</productname>'s text search
13219 facility.
13220 </para>
13222 <table id="textsearch-operators-table">
13223 <title>Text Search Operators</title>
13224 <tgroup cols="1">
13225 <thead>
13226 <row>
13227 <entry role="func_table_entry"><para role="func_signature">
13228 Operator
13229 </para>
13230 <para>
13231 Description
13232 </para>
13233 <para>
13234 Example(s)
13235 </para></entry>
13236 </row>
13237 </thead>
13239 <tbody>
13240 <row>
13241 <entry role="func_table_entry"><para role="func_signature">
13242 <type>tsvector</type> <literal>@@</literal> <type>tsquery</type>
13243 <returnvalue>boolean</returnvalue>
13244 </para>
13245 <para role="func_signature">
13246 <type>tsquery</type> <literal>@@</literal> <type>tsvector</type>
13247 <returnvalue>boolean</returnvalue>
13248 </para>
13249 <para>
13250 Does <type>tsvector</type> match <type>tsquery</type>?
13251 (The arguments can be given in either order.)
13252 </para>
13253 <para>
13254 <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal>
13255 <returnvalue>t</returnvalue>
13256 </para></entry>
13257 </row>
13259 <row>
13260 <entry role="func_table_entry"><para role="func_signature">
13261 <type>text</type> <literal>@@</literal> <type>tsquery</type>
13262 <returnvalue>boolean</returnvalue>
13263 </para>
13264 <para>
13265 Does text string, after implicit invocation
13266 of <function>to_tsvector()</function>, match <type>tsquery</type>?
13267 </para>
13268 <para>
13269 <literal>'fat cats ate rats' @@ to_tsquery('cat &amp; rat')</literal>
13270 <returnvalue>t</returnvalue>
13271 </para></entry>
13272 </row>
13274 <row>
13275 <entry role="func_table_entry"><para role="func_signature">
13276 <type>tsvector</type> <literal>||</literal> <type>tsvector</type>
13277 <returnvalue>tsvector</returnvalue>
13278 </para>
13279 <para>
13280 Concatenates two <type>tsvector</type>s. If both inputs contain
13281 lexeme positions, the second input's positions are adjusted
13282 accordingly.
13283 </para>
13284 <para>
13285 <literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal>
13286 <returnvalue>'a':1 'b':2,5 'c':3 'd':4</returnvalue>
13287 </para></entry>
13288 </row>
13290 <row>
13291 <entry role="func_table_entry"><para role="func_signature">
13292 <type>tsquery</type> <literal>&amp;&amp;</literal> <type>tsquery</type>
13293 <returnvalue>tsquery</returnvalue>
13294 </para>
13295 <para>
13296 ANDs two <type>tsquery</type>s together, producing a query that
13297 matches documents that match both input queries.
13298 </para>
13299 <para>
13300 <literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal>
13301 <returnvalue>( 'fat' | 'rat' ) &amp; 'cat'</returnvalue>
13302 </para></entry>
13303 </row>
13305 <row>
13306 <entry role="func_table_entry"><para role="func_signature">
13307 <type>tsquery</type> <literal>||</literal> <type>tsquery</type>
13308 <returnvalue>tsquery</returnvalue>
13309 </para>
13310 <para>
13311 ORs two <type>tsquery</type>s together, producing a query that
13312 matches documents that match either input query.
13313 </para>
13314 <para>
13315 <literal>'fat | rat'::tsquery || 'cat'::tsquery</literal>
13316 <returnvalue>'fat' | 'rat' | 'cat'</returnvalue>
13317 </para></entry>
13318 </row>
13320 <row>
13321 <entry role="func_table_entry"><para role="func_signature">
13322 <literal>!!</literal> <type>tsquery</type>
13323 <returnvalue>tsquery</returnvalue>
13324 </para>
13325 <para>
13326 Negates a <type>tsquery</type>, producing a query that matches
13327 documents that do not match the input query.
13328 </para>
13329 <para>
13330 <literal>!! 'cat'::tsquery</literal>
13331 <returnvalue>!'cat'</returnvalue>
13332 </para></entry>
13333 </row>
13335 <row>
13336 <entry role="func_table_entry"><para role="func_signature">
13337 <type>tsquery</type> <literal>&lt;-&gt;</literal> <type>tsquery</type>
13338 <returnvalue>tsquery</returnvalue>
13339 </para>
13340 <para>
13341 Constructs a phrase query, which matches if the two input queries
13342 match at successive lexemes.
13343 </para>
13344 <para>
13345 <literal>to_tsquery('fat') &lt;-&gt; to_tsquery('rat')</literal>
13346 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
13347 </para></entry>
13348 </row>
13350 <row>
13351 <entry role="func_table_entry"><para role="func_signature">
13352 <type>tsquery</type> <literal>@&gt;</literal> <type>tsquery</type>
13353 <returnvalue>boolean</returnvalue>
13354 </para>
13355 <para>
13356 Does first <type>tsquery</type> contain the second? (This considers
13357 only whether all the lexemes appearing in one query appear in the
13358 other, ignoring the combining operators.)
13359 </para>
13360 <para>
13361 <literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal>
13362 <returnvalue>f</returnvalue>
13363 </para></entry>
13364 </row>
13366 <row>
13367 <entry role="func_table_entry"><para role="func_signature">
13368 <type>tsquery</type> <literal>&lt;@</literal> <type>tsquery</type>
13369 <returnvalue>boolean</returnvalue>
13370 </para>
13371 <para>
13372 Is first <type>tsquery</type> contained in the second? (This
13373 considers only whether all the lexemes appearing in one query appear
13374 in the other, ignoring the combining operators.)
13375 </para>
13376 <para>
13377 <literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal>
13378 <returnvalue>t</returnvalue>
13379 </para>
13380 <para>
13381 <literal>'cat'::tsquery &lt;@ '!cat &amp; rat'::tsquery</literal>
13382 <returnvalue>t</returnvalue>
13383 </para></entry>
13384 </row>
13385 </tbody>
13386 </tgroup>
13387 </table>
13389 <para>
13390 In addition to these specialized operators, the usual comparison
13391 operators shown in <xref linkend="functions-comparison-op-table"/> are
13392 available for types <type>tsvector</type> and <type>tsquery</type>.
13393 These are not very
13394 useful for text searching but allow, for example, unique indexes to be
13395 built on columns of these types.
13396 </para>
13398 <table id="textsearch-functions-table">
13399 <title>Text Search Functions</title>
13400 <tgroup cols="1">
13401 <thead>
13402 <row>
13403 <entry role="func_table_entry"><para role="func_signature">
13404 Function
13405 </para>
13406 <para>
13407 Description
13408 </para>
13409 <para>
13410 Example(s)
13411 </para></entry>
13412 </row>
13413 </thead>
13415 <tbody>
13416 <row>
13417 <entry role="func_table_entry"><para role="func_signature">
13418 <indexterm>
13419 <primary>array_to_tsvector</primary>
13420 </indexterm>
13421 <function>array_to_tsvector</function> ( <type>text[]</type> )
13422 <returnvalue>tsvector</returnvalue>
13423 </para>
13424 <para>
13425 Converts an array of text strings to a <type>tsvector</type>.
13426 The given strings are used as lexemes as-is, without further
13427 processing. Array elements must not be empty strings
13428 or <literal>NULL</literal>.
13429 </para>
13430 <para>
13431 <literal>array_to_tsvector('{fat,cat,rat}'::text[])</literal>
13432 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13433 </para></entry>
13434 </row>
13436 <row>
13437 <entry role="func_table_entry"><para role="func_signature">
13438 <indexterm>
13439 <primary>get_current_ts_config</primary>
13440 </indexterm>
13441 <function>get_current_ts_config</function> ( )
13442 <returnvalue>regconfig</returnvalue>
13443 </para>
13444 <para>
13445 Returns the OID of the current default text search configuration
13446 (as set by <xref linkend="guc-default-text-search-config"/>).
13447 </para>
13448 <para>
13449 <literal>get_current_ts_config()</literal>
13450 <returnvalue>english</returnvalue>
13451 </para></entry>
13452 </row>
13454 <row>
13455 <entry role="func_table_entry"><para role="func_signature">
13456 <indexterm>
13457 <primary>length</primary>
13458 </indexterm>
13459 <function>length</function> ( <type>tsvector</type> )
13460 <returnvalue>integer</returnvalue>
13461 </para>
13462 <para>
13463 Returns the number of lexemes in the <type>tsvector</type>.
13464 </para>
13465 <para>
13466 <literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13467 <returnvalue>3</returnvalue>
13468 </para></entry>
13469 </row>
13471 <row>
13472 <entry role="func_table_entry"><para role="func_signature">
13473 <indexterm>
13474 <primary>numnode</primary>
13475 </indexterm>
13476 <function>numnode</function> ( <type>tsquery</type> )
13477 <returnvalue>integer</returnvalue>
13478 </para>
13479 <para>
13480 Returns the number of lexemes plus operators in
13481 the <type>tsquery</type>.
13482 </para>
13483 <para>
13484 <literal>numnode('(fat &amp; rat) | cat'::tsquery)</literal>
13485 <returnvalue>5</returnvalue>
13486 </para></entry>
13487 </row>
13489 <row>
13490 <entry role="func_table_entry"><para role="func_signature">
13491 <indexterm>
13492 <primary>plainto_tsquery</primary>
13493 </indexterm>
13494 <function>plainto_tsquery</function> (
13495 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13496 <parameter>query</parameter> <type>text</type> )
13497 <returnvalue>tsquery</returnvalue>
13498 </para>
13499 <para>
13500 Converts text to a <type>tsquery</type>, normalizing words according to
13501 the specified or default configuration. Any punctuation in the string
13502 is ignored (it does not determine query operators). The resulting
13503 query matches documents containing all non-stopwords in the text.
13504 </para>
13505 <para>
13506 <literal>plainto_tsquery('english', 'The Fat Rats')</literal>
13507 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13508 </para></entry>
13509 </row>
13511 <row>
13512 <entry role="func_table_entry"><para role="func_signature">
13513 <indexterm>
13514 <primary>phraseto_tsquery</primary>
13515 </indexterm>
13516 <function>phraseto_tsquery</function> (
13517 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13518 <parameter>query</parameter> <type>text</type> )
13519 <returnvalue>tsquery</returnvalue>
13520 </para>
13521 <para>
13522 Converts text to a <type>tsquery</type>, normalizing words according to
13523 the specified or default configuration. Any punctuation in the string
13524 is ignored (it does not determine query operators). The resulting
13525 query matches phrases containing all non-stopwords in the text.
13526 </para>
13527 <para>
13528 <literal>phraseto_tsquery('english', 'The Fat Rats')</literal>
13529 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
13530 </para>
13531 <para>
13532 <literal>phraseto_tsquery('english', 'The Cat and Rats')</literal>
13533 <returnvalue>'cat' &lt;2&gt; 'rat'</returnvalue>
13534 </para></entry>
13535 </row>
13537 <row>
13538 <entry role="func_table_entry"><para role="func_signature">
13539 <indexterm>
13540 <primary>websearch_to_tsquery</primary>
13541 </indexterm>
13542 <function>websearch_to_tsquery</function> (
13543 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13544 <parameter>query</parameter> <type>text</type> )
13545 <returnvalue>tsquery</returnvalue>
13546 </para>
13547 <para>
13548 Converts text to a <type>tsquery</type>, normalizing words according
13549 to the specified or default configuration. Quoted word sequences are
13550 converted to phrase tests. The word <quote>or</quote> is understood
13551 as producing an OR operator, and a dash produces a NOT operator;
13552 other punctuation is ignored.
13553 This approximates the behavior of some common web search tools.
13554 </para>
13555 <para>
13556 <literal>websearch_to_tsquery('english', '"fat rat" or cat dog')</literal>
13557 <returnvalue>'fat' &lt;-&gt; 'rat' | 'cat' &amp; 'dog'</returnvalue>
13558 </para></entry>
13559 </row>
13561 <row>
13562 <entry role="func_table_entry"><para role="func_signature">
13563 <indexterm>
13564 <primary>querytree</primary>
13565 </indexterm>
13566 <function>querytree</function> ( <type>tsquery</type> )
13567 <returnvalue>text</returnvalue>
13568 </para>
13569 <para>
13570 Produces a representation of the indexable portion of
13571 a <type>tsquery</type>. A result that is empty or
13572 just <literal>T</literal> indicates a non-indexable query.
13573 </para>
13574 <para>
13575 <literal>querytree('foo &amp; ! bar'::tsquery)</literal>
13576 <returnvalue>'foo'</returnvalue>
13577 </para></entry>
13578 </row>
13580 <row>
13581 <entry role="func_table_entry"><para role="func_signature">
13582 <indexterm>
13583 <primary>setweight</primary>
13584 </indexterm>
13585 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type> )
13586 <returnvalue>tsvector</returnvalue>
13587 </para>
13588 <para>
13589 Assigns the specified <parameter>weight</parameter> to each element
13590 of the <parameter>vector</parameter>.
13591 </para>
13592 <para>
13593 <literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal>
13594 <returnvalue>'cat':3A 'fat':2A,4A 'rat':5A</returnvalue>
13595 </para></entry>
13596 </row>
13598 <row>
13599 <entry role="func_table_entry"><para role="func_signature">
13600 <indexterm>
13601 <primary>setweight</primary>
13602 <secondary>setweight for specific lexeme(s)</secondary>
13603 </indexterm>
13604 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13605 <returnvalue>tsvector</returnvalue>
13606 </para>
13607 <para>
13608 Assigns the specified <parameter>weight</parameter> to elements
13609 of the <parameter>vector</parameter> that are listed
13610 in <parameter>lexemes</parameter>.
13611 The strings in <parameter>lexemes</parameter> are taken as lexemes
13612 as-is, without further processing. Strings that do not match any
13613 lexeme in <parameter>vector</parameter> are ignored.
13614 </para>
13615 <para>
13616 <literal>setweight('fat:2,4 cat:3 rat:5,6B'::tsvector, 'A', '{cat,rat}')</literal>
13617 <returnvalue>'cat':3A 'fat':2,4 'rat':5A,6A</returnvalue>
13618 </para></entry>
13619 </row>
13621 <row>
13622 <entry role="func_table_entry"><para role="func_signature">
13623 <indexterm>
13624 <primary>strip</primary>
13625 </indexterm>
13626 <function>strip</function> ( <type>tsvector</type> )
13627 <returnvalue>tsvector</returnvalue>
13628 </para>
13629 <para>
13630 Removes positions and weights from the <type>tsvector</type>.
13631 </para>
13632 <para>
13633 <literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13634 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13635 </para></entry>
13636 </row>
13638 <row>
13639 <entry role="func_table_entry"><para role="func_signature">
13640 <indexterm>
13641 <primary>to_tsquery</primary>
13642 </indexterm>
13643 <function>to_tsquery</function> (
13644 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13645 <parameter>query</parameter> <type>text</type> )
13646 <returnvalue>tsquery</returnvalue>
13647 </para>
13648 <para>
13649 Converts text to a <type>tsquery</type>, normalizing words according to
13650 the specified or default configuration. The words must be combined
13651 by valid <type>tsquery</type> operators.
13652 </para>
13653 <para>
13654 <literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal>
13655 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13656 </para></entry>
13657 </row>
13659 <row>
13660 <entry role="func_table_entry"><para role="func_signature">
13661 <indexterm>
13662 <primary>to_tsvector</primary>
13663 </indexterm>
13664 <function>to_tsvector</function> (
13665 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13666 <parameter>document</parameter> <type>text</type> )
13667 <returnvalue>tsvector</returnvalue>
13668 </para>
13669 <para>
13670 Converts text to a <type>tsvector</type>, normalizing words according
13671 to the specified or default configuration. Position information is
13672 included in the result.
13673 </para>
13674 <para>
13675 <literal>to_tsvector('english', 'The Fat Rats')</literal>
13676 <returnvalue>'fat':2 'rat':3</returnvalue>
13677 </para></entry>
13678 </row>
13680 <row>
13681 <entry role="func_table_entry"><para role="func_signature">
13682 <function>to_tsvector</function> (
13683 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13684 <parameter>document</parameter> <type>json</type> )
13685 <returnvalue>tsvector</returnvalue>
13686 </para>
13687 <para role="func_signature">
13688 <function>to_tsvector</function> (
13689 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13690 <parameter>document</parameter> <type>jsonb</type> )
13691 <returnvalue>tsvector</returnvalue>
13692 </para>
13693 <para>
13694 Converts each string value in the JSON document to
13695 a <type>tsvector</type>, normalizing words according to the specified
13696 or default configuration. The results are then concatenated in
13697 document order to produce the output. Position information is
13698 generated as though one stopword exists between each pair of string
13699 values. (Beware that <quote>document order</quote> of the fields of a
13700 JSON object is implementation-dependent when the input
13701 is <type>jsonb</type>; observe the difference in the examples.)
13702 </para>
13703 <para>
13704 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::json)</literal>
13705 <returnvalue>'dog':5 'fat':2 'rat':3</returnvalue>
13706 </para>
13707 <para>
13708 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::jsonb)</literal>
13709 <returnvalue>'dog':1 'fat':4 'rat':5</returnvalue>
13710 </para></entry>
13711 </row>
13713 <row>
13714 <entry role="func_table_entry"><para role="func_signature">
13715 <indexterm>
13716 <primary>json_to_tsvector</primary>
13717 </indexterm>
13718 <function>json_to_tsvector</function> (
13719 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13720 <parameter>document</parameter> <type>json</type>,
13721 <parameter>filter</parameter> <type>jsonb</type> )
13722 <returnvalue>tsvector</returnvalue>
13723 </para>
13724 <para role="func_signature">
13725 <indexterm>
13726 <primary>jsonb_to_tsvector</primary>
13727 </indexterm>
13728 <function>jsonb_to_tsvector</function> (
13729 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13730 <parameter>document</parameter> <type>jsonb</type>,
13731 <parameter>filter</parameter> <type>jsonb</type> )
13732 <returnvalue>tsvector</returnvalue>
13733 </para>
13734 <para>
13735 Selects each item in the JSON document that is requested by
13736 the <parameter>filter</parameter> and converts each one to
13737 a <type>tsvector</type>, normalizing words according to the specified
13738 or default configuration. The results are then concatenated in
13739 document order to produce the output. Position information is
13740 generated as though one stopword exists between each pair of selected
13741 items. (Beware that <quote>document order</quote> of the fields of a
13742 JSON object is implementation-dependent when the input
13743 is <type>jsonb</type>.)
13744 The <parameter>filter</parameter> must be a <type>jsonb</type>
13745 array containing zero or more of these keywords:
13746 <literal>"string"</literal> (to include all string values),
13747 <literal>"numeric"</literal> (to include all numeric values),
13748 <literal>"boolean"</literal> (to include all boolean values),
13749 <literal>"key"</literal> (to include all keys), or
13750 <literal>"all"</literal> (to include all the above).
13751 As a special case, the <parameter>filter</parameter> can also be a
13752 simple JSON value that is one of these keywords.
13753 </para>
13754 <para>
13755 <literal>json_to_tsvector('english', '{"a": "The Fat Rats", "b": 123}'::json, '["string", "numeric"]')</literal>
13756 <returnvalue>'123':5 'fat':2 'rat':3</returnvalue>
13757 </para>
13758 <para>
13759 <literal>json_to_tsvector('english', '{"cat": "The Fat Rats", "dog": 123}'::json, '"all"')</literal>
13760 <returnvalue>'123':9 'cat':1 'dog':7 'fat':4 'rat':5</returnvalue>
13761 </para></entry>
13762 </row>
13764 <row>
13765 <entry role="func_table_entry"><para role="func_signature">
13766 <indexterm>
13767 <primary>ts_delete</primary>
13768 </indexterm>
13769 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexeme</parameter> <type>text</type> )
13770 <returnvalue>tsvector</returnvalue>
13771 </para>
13772 <para>
13773 Removes any occurrence of the given <parameter>lexeme</parameter>
13774 from the <parameter>vector</parameter>.
13775 The <parameter>lexeme</parameter> string is treated as a lexeme as-is,
13776 without further processing.
13777 </para>
13778 <para>
13779 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, 'fat')</literal>
13780 <returnvalue>'cat':3 'rat':5A</returnvalue>
13781 </para></entry>
13782 </row>
13784 <row>
13785 <entry role="func_table_entry"><para role="func_signature">
13786 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13787 <returnvalue>tsvector</returnvalue>
13788 </para>
13789 <para>
13790 Removes any occurrences of the lexemes
13791 in <parameter>lexemes</parameter>
13792 from the <parameter>vector</parameter>.
13793 The strings in <parameter>lexemes</parameter> are taken as lexemes
13794 as-is, without further processing. Strings that do not match any
13795 lexeme in <parameter>vector</parameter> are ignored.
13796 </para>
13797 <para>
13798 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, ARRAY['fat','rat'])</literal>
13799 <returnvalue>'cat':3</returnvalue>
13800 </para></entry>
13801 </row>
13803 <row>
13804 <entry role="func_table_entry"><para role="func_signature">
13805 <indexterm>
13806 <primary>ts_filter</primary>
13807 </indexterm>
13808 <function>ts_filter</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weights</parameter> <type>"char"[]</type> )
13809 <returnvalue>tsvector</returnvalue>
13810 </para>
13811 <para>
13812 Selects only elements with the given <parameter>weights</parameter>
13813 from the <parameter>vector</parameter>.
13814 </para>
13815 <para>
13816 <literal>ts_filter('fat:2,4 cat:3b,7c rat:5A'::tsvector, '{a,b}')</literal>
13817 <returnvalue>'cat':3B 'rat':5A</returnvalue>
13818 </para></entry>
13819 </row>
13821 <row>
13822 <entry role="func_table_entry"><para role="func_signature">
13823 <indexterm>
13824 <primary>ts_headline</primary>
13825 </indexterm>
13826 <function>ts_headline</function> (
13827 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13828 <parameter>document</parameter> <type>text</type>,
13829 <parameter>query</parameter> <type>tsquery</type>
13830 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13831 <returnvalue>text</returnvalue>
13832 </para>
13833 <para>
13834 Displays, in an abbreviated form, the match(es) for
13835 the <parameter>query</parameter> in
13836 the <parameter>document</parameter>, which must be raw text not
13837 a <type>tsvector</type>. Words in the document are normalized
13838 according to the specified or default configuration before matching to
13839 the query. Use of this function is discussed in
13840 <xref linkend="textsearch-headline"/>, which also describes the
13841 available <parameter>options</parameter>.
13842 </para>
13843 <para>
13844 <literal>ts_headline('The fat cat ate the rat.', 'cat')</literal>
13845 <returnvalue>The fat &lt;b&gt;cat&lt;/b&gt; ate the rat.</returnvalue>
13846 </para></entry>
13847 </row>
13849 <row>
13850 <entry role="func_table_entry"><para role="func_signature">
13851 <function>ts_headline</function> (
13852 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13853 <parameter>document</parameter> <type>json</type>,
13854 <parameter>query</parameter> <type>tsquery</type>
13855 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13856 <returnvalue>text</returnvalue>
13857 </para>
13858 <para role="func_signature">
13859 <function>ts_headline</function> (
13860 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13861 <parameter>document</parameter> <type>jsonb</type>,
13862 <parameter>query</parameter> <type>tsquery</type>
13863 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13864 <returnvalue>text</returnvalue>
13865 </para>
13866 <para>
13867 Displays, in an abbreviated form, match(es) for
13868 the <parameter>query</parameter> that occur in string values
13869 within the JSON <parameter>document</parameter>.
13870 See <xref linkend="textsearch-headline"/> for more details.
13871 </para>
13872 <para>
13873 <literal>ts_headline('{"cat":"raining cats and dogs"}'::jsonb, 'cat')</literal>
13874 <returnvalue>{"cat": "raining &lt;b&gt;cats&lt;/b&gt; and dogs"}</returnvalue>
13875 </para></entry>
13876 </row>
13878 <row>
13879 <entry role="func_table_entry"><para role="func_signature">
13880 <indexterm>
13881 <primary>ts_rank</primary>
13882 </indexterm>
13883 <function>ts_rank</function> (
13884 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13885 <parameter>vector</parameter> <type>tsvector</type>,
13886 <parameter>query</parameter> <type>tsquery</type>
13887 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13888 <returnvalue>real</returnvalue>
13889 </para>
13890 <para>
13891 Computes a score showing how well
13892 the <parameter>vector</parameter> matches
13893 the <parameter>query</parameter>. See
13894 <xref linkend="textsearch-ranking"/> for details.
13895 </para>
13896 <para>
13897 <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')</literal>
13898 <returnvalue>0.06079271</returnvalue>
13899 </para></entry>
13900 </row>
13902 <row>
13903 <entry role="func_table_entry"><para role="func_signature">
13904 <indexterm>
13905 <primary>ts_rank_cd</primary>
13906 </indexterm>
13907 <function>ts_rank_cd</function> (
13908 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13909 <parameter>vector</parameter> <type>tsvector</type>,
13910 <parameter>query</parameter> <type>tsquery</type>
13911 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13912 <returnvalue>real</returnvalue>
13913 </para>
13914 <para>
13915 Computes a score showing how well
13916 the <parameter>vector</parameter> matches
13917 the <parameter>query</parameter>, using a cover density
13918 algorithm. See <xref linkend="textsearch-ranking"/> for details.
13919 </para>
13920 <para>
13921 <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')</literal>
13922 <returnvalue>0.1</returnvalue>
13923 </para></entry>
13924 </row>
13926 <row>
13927 <entry role="func_table_entry"><para role="func_signature">
13928 <indexterm>
13929 <primary>ts_rewrite</primary>
13930 </indexterm>
13931 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13932 <parameter>target</parameter> <type>tsquery</type>,
13933 <parameter>substitute</parameter> <type>tsquery</type> )
13934 <returnvalue>tsquery</returnvalue>
13935 </para>
13936 <para>
13937 Replaces occurrences of <parameter>target</parameter>
13938 with <parameter>substitute</parameter>
13939 within the <parameter>query</parameter>.
13940 See <xref linkend="textsearch-query-rewriting"/> for details.
13941 </para>
13942 <para>
13943 <literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal>
13944 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13945 </para></entry>
13946 </row>
13948 <row>
13949 <entry role="func_table_entry"><para role="func_signature">
13950 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13951 <parameter>select</parameter> <type>text</type> )
13952 <returnvalue>tsquery</returnvalue>
13953 </para>
13954 <para>
13955 Replaces portions of the <parameter>query</parameter> according to
13956 target(s) and substitute(s) obtained by executing
13957 a <command>SELECT</command> command.
13958 See <xref linkend="textsearch-query-rewriting"/> for details.
13959 </para>
13960 <para>
13961 <literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal>
13962 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13963 </para></entry>
13964 </row>
13966 <row>
13967 <entry role="func_table_entry"><para role="func_signature">
13968 <indexterm>
13969 <primary>tsquery_phrase</primary>
13970 </indexterm>
13971 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type> )
13972 <returnvalue>tsquery</returnvalue>
13973 </para>
13974 <para>
13975 Constructs a phrase query that searches
13976 for matches of <parameter>query1</parameter>
13977 and <parameter>query2</parameter> at successive lexemes (same
13978 as <literal>&lt;-&gt;</literal> operator).
13979 </para>
13980 <para>
13981 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))</literal>
13982 <returnvalue>'fat' &lt;-&gt; 'cat'</returnvalue>
13983 </para></entry>
13984 </row>
13986 <row>
13987 <entry role="func_table_entry"><para role="func_signature">
13988 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type>, <parameter>distance</parameter> <type>integer</type> )
13989 <returnvalue>tsquery</returnvalue>
13990 </para>
13991 <para>
13992 Constructs a phrase query that searches
13993 for matches of <parameter>query1</parameter> and
13994 <parameter>query2</parameter> that occur exactly
13995 <parameter>distance</parameter> lexemes apart.
13996 </para>
13997 <para>
13998 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'), 10)</literal>
13999 <returnvalue>'fat' &lt;10&gt; 'cat'</returnvalue>
14000 </para></entry>
14001 </row>
14003 <row>
14004 <entry role="func_table_entry"><para role="func_signature">
14005 <indexterm>
14006 <primary>tsvector_to_array</primary>
14007 </indexterm>
14008 <function>tsvector_to_array</function> ( <type>tsvector</type> )
14009 <returnvalue>text[]</returnvalue>
14010 </para>
14011 <para>
14012 Converts a <type>tsvector</type> to an array of lexemes.
14013 </para>
14014 <para>
14015 <literal>tsvector_to_array('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
14016 <returnvalue>{cat,fat,rat}</returnvalue>
14017 </para></entry>
14018 </row>
14020 <row>
14021 <entry role="func_table_entry"><para role="func_signature">
14022 <indexterm>
14023 <primary>unnest</primary>
14024 <secondary>for tsvector</secondary>
14025 </indexterm>
14026 <function>unnest</function> ( <type>tsvector</type> )
14027 <returnvalue>setof record</returnvalue>
14028 ( <parameter>lexeme</parameter> <type>text</type>,
14029 <parameter>positions</parameter> <type>smallint[]</type>,
14030 <parameter>weights</parameter> <type>text</type> )
14031 </para>
14032 <para>
14033 Expands a <type>tsvector</type> into a set of rows, one per lexeme.
14034 </para>
14035 <para>
14036 <literal>select * from unnest('cat:3 fat:2,4 rat:5A'::tsvector)</literal>
14037 <returnvalue></returnvalue>
14038 <programlisting>
14039 lexeme | positions | weights
14040 --------+-----------+---------
14041 cat | {3} | {D}
14042 fat | {2,4} | {D,D}
14043 rat | {5} | {A}
14044 </programlisting>
14045 </para></entry>
14046 </row>
14047 </tbody>
14048 </tgroup>
14049 </table>
14051 <note>
14052 <para>
14053 All the text search functions that accept an optional <type>regconfig</type>
14054 argument will use the configuration specified by
14055 <xref linkend="guc-default-text-search-config"/>
14056 when that argument is omitted.
14057 </para>
14058 </note>
14060 <para>
14061 The functions in
14062 <xref linkend="textsearch-functions-debug-table"/>
14063 are listed separately because they are not usually used in everyday text
14064 searching operations. They are primarily helpful for development and
14065 debugging of new text search configurations.
14066 </para>
14068 <table id="textsearch-functions-debug-table">
14069 <title>Text Search Debugging Functions</title>
14070 <tgroup cols="1">
14071 <thead>
14072 <row>
14073 <entry role="func_table_entry"><para role="func_signature">
14074 Function
14075 </para>
14076 <para>
14077 Description
14078 </para>
14079 <para>
14080 Example(s)
14081 </para></entry>
14082 </row>
14083 </thead>
14085 <tbody>
14086 <row>
14087 <entry role="func_table_entry"><para role="func_signature">
14088 <indexterm>
14089 <primary>ts_debug</primary>
14090 </indexterm>
14091 <function>ts_debug</function> (
14092 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
14093 <parameter>document</parameter> <type>text</type> )
14094 <returnvalue>setof record</returnvalue>
14095 ( <parameter>alias</parameter> <type>text</type>,
14096 <parameter>description</parameter> <type>text</type>,
14097 <parameter>token</parameter> <type>text</type>,
14098 <parameter>dictionaries</parameter> <type>regdictionary[]</type>,
14099 <parameter>dictionary</parameter> <type>regdictionary</type>,
14100 <parameter>lexemes</parameter> <type>text[]</type> )
14101 </para>
14102 <para>
14103 Extracts and normalizes tokens from
14104 the <parameter>document</parameter> according to the specified or
14105 default text search configuration, and returns information about how
14106 each token was processed.
14107 See <xref linkend="textsearch-configuration-testing"/> for details.
14108 </para>
14109 <para>
14110 <literal>ts_debug('english', 'The Brightest supernovaes')</literal>
14111 <returnvalue>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</returnvalue>
14112 </para></entry>
14113 </row>
14115 <row>
14116 <entry role="func_table_entry"><para role="func_signature">
14117 <indexterm>
14118 <primary>ts_lexize</primary>
14119 </indexterm>
14120 <function>ts_lexize</function> ( <parameter>dict</parameter> <type>regdictionary</type>, <parameter>token</parameter> <type>text</type> )
14121 <returnvalue>text[]</returnvalue>
14122 </para>
14123 <para>
14124 Returns an array of replacement lexemes if the input token is known to
14125 the dictionary, or an empty array if the token is known to the
14126 dictionary but it is a stop word, or NULL if it is not a known word.
14127 See <xref linkend="textsearch-dictionary-testing"/> for details.
14128 </para>
14129 <para>
14130 <literal>ts_lexize('english_stem', 'stars')</literal>
14131 <returnvalue>{star}</returnvalue>
14132 </para></entry>
14133 </row>
14135 <row>
14136 <entry role="func_table_entry"><para role="func_signature">
14137 <indexterm>
14138 <primary>ts_parse</primary>
14139 </indexterm>
14140 <function>ts_parse</function> ( <parameter>parser_name</parameter> <type>text</type>,
14141 <parameter>document</parameter> <type>text</type> )
14142 <returnvalue>setof record</returnvalue>
14143 ( <parameter>tokid</parameter> <type>integer</type>,
14144 <parameter>token</parameter> <type>text</type> )
14145 </para>
14146 <para>
14147 Extracts tokens from the <parameter>document</parameter> using the
14148 named parser.
14149 See <xref linkend="textsearch-parser-testing"/> for details.
14150 </para>
14151 <para>
14152 <literal>ts_parse('default', 'foo - bar')</literal>
14153 <returnvalue>(1,foo) ...</returnvalue>
14154 </para></entry>
14155 </row>
14157 <row>
14158 <entry role="func_table_entry"><para role="func_signature">
14159 <function>ts_parse</function> ( <parameter>parser_oid</parameter> <type>oid</type>,
14160 <parameter>document</parameter> <type>text</type> )
14161 <returnvalue>setof record</returnvalue>
14162 ( <parameter>tokid</parameter> <type>integer</type>,
14163 <parameter>token</parameter> <type>text</type> )
14164 </para>
14165 <para>
14166 Extracts tokens from the <parameter>document</parameter> using a
14167 parser specified by OID.
14168 See <xref linkend="textsearch-parser-testing"/> for details.
14169 </para>
14170 <para>
14171 <literal>ts_parse(3722, 'foo - bar')</literal>
14172 <returnvalue>(1,foo) ...</returnvalue>
14173 </para></entry>
14174 </row>
14176 <row>
14177 <entry role="func_table_entry"><para role="func_signature">
14178 <indexterm>
14179 <primary>ts_token_type</primary>
14180 </indexterm>
14181 <function>ts_token_type</function> ( <parameter>parser_name</parameter> <type>text</type> )
14182 <returnvalue>setof record</returnvalue>
14183 ( <parameter>tokid</parameter> <type>integer</type>,
14184 <parameter>alias</parameter> <type>text</type>,
14185 <parameter>description</parameter> <type>text</type> )
14186 </para>
14187 <para>
14188 Returns a table that describes each type of token the named parser can
14189 recognize.
14190 See <xref linkend="textsearch-parser-testing"/> for details.
14191 </para>
14192 <para>
14193 <literal>ts_token_type('default')</literal>
14194 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
14195 </para></entry>
14196 </row>
14198 <row>
14199 <entry role="func_table_entry"><para role="func_signature">
14200 <function>ts_token_type</function> ( <parameter>parser_oid</parameter> <type>oid</type> )
14201 <returnvalue>setof record</returnvalue>
14202 ( <parameter>tokid</parameter> <type>integer</type>,
14203 <parameter>alias</parameter> <type>text</type>,
14204 <parameter>description</parameter> <type>text</type> )
14205 </para>
14206 <para>
14207 Returns a table that describes each type of token a parser specified
14208 by OID can recognize.
14209 See <xref linkend="textsearch-parser-testing"/> for details.
14210 </para>
14211 <para>
14212 <literal>ts_token_type(3722)</literal>
14213 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
14214 </para></entry>
14215 </row>
14217 <row>
14218 <entry role="func_table_entry"><para role="func_signature">
14219 <indexterm>
14220 <primary>ts_stat</primary>
14221 </indexterm>
14222 <function>ts_stat</function> ( <parameter>sqlquery</parameter> <type>text</type>
14223 <optional>, <parameter>weights</parameter> <type>text</type> </optional> )
14224 <returnvalue>setof record</returnvalue>
14225 ( <parameter>word</parameter> <type>text</type>,
14226 <parameter>ndoc</parameter> <type>integer</type>,
14227 <parameter>nentry</parameter> <type>integer</type> )
14228 </para>
14229 <para>
14230 Executes the <parameter>sqlquery</parameter>, which must return a
14231 single <type>tsvector</type> column, and returns statistics about each
14232 distinct lexeme contained in the data.
14233 See <xref linkend="textsearch-statistics"/> for details.
14234 </para>
14235 <para>
14236 <literal>ts_stat('SELECT vector FROM apod')</literal>
14237 <returnvalue>(foo,10,15) ...</returnvalue>
14238 </para></entry>
14239 </row>
14240 </tbody>
14241 </tgroup>
14242 </table>
14244 </sect1>
14246 <sect1 id="functions-uuid">
14247 <title>UUID Functions</title>
14249 <indexterm zone="datatype-uuid">
14250 <primary>UUID</primary>
14251 <secondary>generating</secondary>
14252 </indexterm>
14254 <indexterm>
14255 <primary>gen_random_uuid</primary>
14256 </indexterm>
14258 <indexterm>
14259 <primary>uuidv4</primary>
14260 </indexterm>
14262 <indexterm>
14263 <primary>uuidv7</primary>
14264 </indexterm>
14266 <indexterm>
14267 <primary>uuid_extract_timestamp</primary>
14268 </indexterm>
14270 <indexterm>
14271 <primary>uuid_extract_version</primary>
14272 </indexterm>
14274 <para>
14275 <productname>PostgreSQL</productname> includes several functions to generate a UUID.
14276 <synopsis>
14277 <function>gen_random_uuid</function> () <returnvalue>uuid</returnvalue>
14278 <function>uuidv4</function> () <returnvalue>uuid</returnvalue>
14279 </synopsis>
14280 These functions return a version 4 (random) UUID.
14281 <synopsis>
14282 <function>uuidv7</function> (<optional> <parameter>shift</parameter> <type>interval</type> </optional>) <returnvalue>uuid</returnvalue>
14283 </synopsis>
14284 This function returns a version 7 UUID (UNIX timestamp with millisecond
14285 precision + sub-millisecond timestamp + random). This function can accept
14286 optional <parameter>shift</parameter> parameter of type <type>interval</type>
14287 which shift internal timestamp by the given interval.
14288 </para>
14290 <para>
14291 The <xref linkend="uuid-ossp"/> module provides additional functions that
14292 implement other standard algorithms for generating UUIDs.
14293 </para>
14295 <para>
14296 There are also functions to extract data from UUIDs:
14297 <synopsis>
14298 <function>uuid_extract_timestamp</function> (uuid) <returnvalue>timestamp with time zone</returnvalue>
14299 </synopsis>
14300 This function extracts a <type>timestamp with time zone</type> from UUID
14301 version 1 and 7. For other versions, this function returns null. Note that
14302 the extracted timestamp is not necessarily exactly equal to the time the
14303 UUID was generated; this depends on the implementation that generated the
14304 UUID.
14305 </para>
14307 <para>
14308 <synopsis>
14309 <function>uuid_extract_version</function> (uuid) <returnvalue>smallint</returnvalue>
14310 </synopsis>
14311 This function extracts the version from a UUID of the variant described by
14312 <ulink url="https://datatracker.ietf.org/doc/html/rfc9562">RFC 9562</ulink>. For
14313 other variants, this function returns null. For example, for a UUID
14314 generated by <function>gen_random_uuid</function>, this function will
14315 return 4.
14316 </para>
14318 <para>
14319 <productname>PostgreSQL</productname> also provides the usual comparison
14320 operators shown in <xref linkend="functions-comparison-op-table"/> for
14321 UUIDs.
14322 </para>
14323 </sect1>
14325 <sect1 id="functions-xml">
14327 <title>XML Functions</title>
14329 <indexterm>
14330 <primary>XML Functions</primary>
14331 </indexterm>
14333 <para>
14334 The functions and function-like expressions described in this
14335 section operate on values of type <type>xml</type>. See <xref
14336 linkend="datatype-xml"/> for information about the <type>xml</type>
14337 type. The function-like expressions <function>xmlparse</function>
14338 and <function>xmlserialize</function> for converting to and from
14339 type <type>xml</type> are documented there, not in this section.
14340 </para>
14342 <para>
14343 Use of most of these functions
14344 requires <productname>PostgreSQL</productname> to have been built
14345 with <command>configure --with-libxml</command>.
14346 </para>
14348 <sect2 id="functions-producing-xml">
14349 <title>Producing XML Content</title>
14351 <para>
14352 A set of functions and function-like expressions is available for
14353 producing XML content from SQL data. As such, they are
14354 particularly suitable for formatting query results into XML
14355 documents for processing in client applications.
14356 </para>
14358 <sect3 id="functions-producing-xml-xmltext">
14359 <title><literal>xmltext</literal></title>
14361 <indexterm>
14362 <primary>xmltext</primary>
14363 </indexterm>
14365 <synopsis>
14366 <function>xmltext</function> ( <type>text</type> ) <returnvalue>xml</returnvalue>
14367 </synopsis>
14369 <para>
14370 The function <function>xmltext</function> returns an XML value with a single
14371 text node containing the input argument as its content. Predefined entities
14372 like ampersand (<literal><![CDATA[&]]></literal>), left and right angle brackets
14373 (<literal><![CDATA[< >]]></literal>), and quotation marks (<literal><![CDATA[""]]></literal>)
14374 are escaped.
14375 </para>
14377 <para>
14378 Example:
14379 <screen><![CDATA[
14380 SELECT xmltext('< foo & bar >');
14381 xmltext
14382 -------------------------
14383 &lt; foo &amp; bar &gt;
14384 ]]></screen>
14385 </para>
14386 </sect3>
14388 <sect3 id="functions-producing-xml-xmlcomment">
14389 <title><literal>xmlcomment</literal></title>
14391 <indexterm>
14392 <primary>xmlcomment</primary>
14393 </indexterm>
14395 <synopsis>
14396 <function>xmlcomment</function> ( <type>text</type> ) <returnvalue>xml</returnvalue>
14397 </synopsis>
14399 <para>
14400 The function <function>xmlcomment</function> creates an XML value
14401 containing an XML comment with the specified text as content.
14402 The text cannot contain <quote><literal>--</literal></quote> or end with a
14403 <quote><literal>-</literal></quote>, otherwise the resulting construct
14404 would not be a valid XML comment.
14405 If the argument is null, the result is null.
14406 </para>
14408 <para>
14409 Example:
14410 <screen><![CDATA[
14411 SELECT xmlcomment('hello');
14413 xmlcomment
14414 --------------
14415 <!--hello-->
14416 ]]></screen>
14417 </para>
14418 </sect3>
14420 <sect3 id="functions-producing-xml-xmlconcat">
14421 <title><literal>xmlconcat</literal></title>
14423 <indexterm>
14424 <primary>xmlconcat</primary>
14425 </indexterm>
14427 <synopsis>
14428 <function>xmlconcat</function> ( <type>xml</type> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
14429 </synopsis>
14431 <para>
14432 The function <function>xmlconcat</function> concatenates a list
14433 of individual XML values to create a single value containing an
14434 XML content fragment. Null values are omitted; the result is
14435 only null if there are no nonnull arguments.
14436 </para>
14438 <para>
14439 Example:
14440 <screen><![CDATA[
14441 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
14443 xmlconcat
14444 ----------------------
14445 <abc/><bar>foo</bar>
14446 ]]></screen>
14447 </para>
14449 <para>
14450 XML declarations, if present, are combined as follows. If all
14451 argument values have the same XML version declaration, that
14452 version is used in the result, else no version is used. If all
14453 argument values have the standalone declaration value
14454 <quote>yes</quote>, then that value is used in the result. If
14455 all argument values have a standalone declaration value and at
14456 least one is <quote>no</quote>, then that is used in the result.
14457 Else the result will have no standalone declaration. If the
14458 result is determined to require a standalone declaration but no
14459 version declaration, a version declaration with version 1.0 will
14460 be used because XML requires an XML declaration to contain a
14461 version declaration. Encoding declarations are ignored and
14462 removed in all cases.
14463 </para>
14465 <para>
14466 Example:
14467 <screen><![CDATA[
14468 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
14470 xmlconcat
14471 -----------------------------------
14472 <?xml version="1.1"?><foo/><bar/>
14473 ]]></screen>
14474 </para>
14475 </sect3>
14477 <sect3 id="functions-producing-xml-xmlelement">
14478 <title><literal>xmlelement</literal></title>
14480 <indexterm>
14481 <primary>xmlelement</primary>
14482 </indexterm>
14484 <synopsis>
14485 <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>
14486 </synopsis>
14488 <para>
14489 The <function>xmlelement</function> expression produces an XML
14490 element with the given name, attributes, and content.
14491 The <replaceable>name</replaceable>
14492 and <replaceable>attname</replaceable> items shown in the syntax are
14493 simple identifiers, not values. The <replaceable>attvalue</replaceable>
14494 and <replaceable>content</replaceable> items are expressions, which can
14495 yield any <productname>PostgreSQL</productname> data type. The
14496 argument(s) within <literal>XMLATTRIBUTES</literal> generate attributes
14497 of the XML element; the <replaceable>content</replaceable> value(s) are
14498 concatenated to form its content.
14499 </para>
14501 <para>
14502 Examples:
14503 <screen><![CDATA[
14504 SELECT xmlelement(name foo);
14506 xmlelement
14507 ------------
14508 <foo/>
14510 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
14512 xmlelement
14513 ------------------
14514 <foo bar="xyz"/>
14516 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
14518 xmlelement
14519 -------------------------------------
14520 <foo bar="2007-01-26">content</foo>
14521 ]]></screen>
14522 </para>
14524 <para>
14525 Element and attribute names that are not valid XML names are
14526 escaped by replacing the offending characters by the sequence
14527 <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
14528 <replaceable>HHHH</replaceable> is the character's Unicode
14529 codepoint in hexadecimal notation. For example:
14530 <screen><![CDATA[
14531 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
14533 xmlelement
14534 ----------------------------------
14535 <foo_x0024_bar a_x0026_b="xyz"/>
14536 ]]></screen>
14537 </para>
14539 <para>
14540 An explicit attribute name need not be specified if the attribute
14541 value is a column reference, in which case the column's name will
14542 be used as the attribute name by default. In other cases, the
14543 attribute must be given an explicit name. So this example is
14544 valid:
14545 <screen>
14546 CREATE TABLE test (a xml, b xml);
14547 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
14548 </screen>
14549 But these are not:
14550 <screen>
14551 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
14552 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
14553 </screen>
14554 </para>
14556 <para>
14557 Element content, if specified, will be formatted according to
14558 its data type. If the content is itself of type <type>xml</type>,
14559 complex XML documents can be constructed. For example:
14560 <screen><![CDATA[
14561 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
14562 xmlelement(name abc),
14563 xmlcomment('test'),
14564 xmlelement(name xyz));
14566 xmlelement
14567 ----------------------------------------------
14568 <foo bar="xyz"><abc/><!--test--><xyz/></foo>
14569 ]]></screen>
14571 Content of other types will be formatted into valid XML character
14572 data. This means in particular that the characters &lt;, &gt;,
14573 and &amp; will be converted to entities. Binary data (data type
14574 <type>bytea</type>) will be represented in base64 or hex
14575 encoding, depending on the setting of the configuration parameter
14576 <xref linkend="guc-xmlbinary"/>. The particular behavior for
14577 individual data types is expected to evolve in order to align the
14578 PostgreSQL mappings with those specified in SQL:2006 and later,
14579 as discussed in <xref linkend="functions-xml-limits-casts"/>.
14580 </para>
14581 </sect3>
14583 <sect3 id="functions-producing-xml-xmlforest">
14584 <title><literal>xmlforest</literal></title>
14586 <indexterm>
14587 <primary>xmlforest</primary>
14588 </indexterm>
14590 <synopsis>
14591 <function>xmlforest</function> ( <replaceable>content</replaceable> <optional> <literal>AS</literal> <replaceable>name</replaceable> </optional> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
14592 </synopsis>
14594 <para>
14595 The <function>xmlforest</function> expression produces an XML
14596 forest (sequence) of elements using the given names and content.
14597 As for <function>xmlelement</function>,
14598 each <replaceable>name</replaceable> must be a simple identifier, while
14599 the <replaceable>content</replaceable> expressions can have any data
14600 type.
14601 </para>
14603 <para>
14604 Examples:
14605 <screen>
14606 SELECT xmlforest('abc' AS foo, 123 AS bar);
14608 xmlforest
14609 ------------------------------
14610 &lt;foo&gt;abc&lt;/foo&gt;&lt;bar&gt;123&lt;/bar&gt;
14613 SELECT xmlforest(table_name, column_name)
14614 FROM information_schema.columns
14615 WHERE table_schema = 'pg_catalog';
14617 xmlforest
14618 ------------------------------------&zwsp;-----------------------------------
14619 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolname&lt;/column_name&gt;
14620 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolsuper&lt;/column_name&gt;
14622 </screen>
14624 As seen in the second example, the element name can be omitted if
14625 the content value is a column reference, in which case the column
14626 name is used by default. Otherwise, a name must be specified.
14627 </para>
14629 <para>
14630 Element names that are not valid XML names are escaped as shown
14631 for <function>xmlelement</function> above. Similarly, content
14632 data is escaped to make valid XML content, unless it is already
14633 of type <type>xml</type>.
14634 </para>
14636 <para>
14637 Note that XML forests are not valid XML documents if they consist
14638 of more than one element, so it might be useful to wrap
14639 <function>xmlforest</function> expressions in
14640 <function>xmlelement</function>.
14641 </para>
14642 </sect3>
14644 <sect3 id="functions-producing-xml-xmlpi">
14645 <title><literal>xmlpi</literal></title>
14647 <indexterm>
14648 <primary>xmlpi</primary>
14649 </indexterm>
14651 <synopsis>
14652 <function>xmlpi</function> ( <literal>NAME</literal> <replaceable>name</replaceable> <optional>, <replaceable>content</replaceable> </optional> ) <returnvalue>xml</returnvalue>
14653 </synopsis>
14655 <para>
14656 The <function>xmlpi</function> expression creates an XML
14657 processing instruction.
14658 As for <function>xmlelement</function>,
14659 the <replaceable>name</replaceable> must be a simple identifier, while
14660 the <replaceable>content</replaceable> expression can have any data type.
14661 The <replaceable>content</replaceable>, if present, must not contain the
14662 character sequence <literal>?&gt;</literal>.
14663 </para>
14665 <para>
14666 Example:
14667 <screen><![CDATA[
14668 SELECT xmlpi(name php, 'echo "hello world";');
14670 xmlpi
14671 -----------------------------
14672 <?php echo "hello world";?>
14673 ]]></screen>
14674 </para>
14675 </sect3>
14677 <sect3 id="functions-producing-xml-xmlroot">
14678 <title><literal>xmlroot</literal></title>
14680 <indexterm>
14681 <primary>xmlroot</primary>
14682 </indexterm>
14684 <synopsis>
14685 <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>
14686 </synopsis>
14688 <para>
14689 The <function>xmlroot</function> expression alters the properties
14690 of the root node of an XML value. If a version is specified,
14691 it replaces the value in the root node's version declaration; if a
14692 standalone setting is specified, it replaces the value in the
14693 root node's standalone declaration.
14694 </para>
14696 <para>
14697 <screen><![CDATA[
14698 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
14699 version '1.0', standalone yes);
14701 xmlroot
14702 ----------------------------------------
14703 <?xml version="1.0" standalone="yes"?>
14704 <content>abc</content>
14705 ]]></screen>
14706 </para>
14707 </sect3>
14709 <sect3 id="functions-xml-xmlagg">
14710 <title><literal>xmlagg</literal></title>
14712 <indexterm>
14713 <primary>xmlagg</primary>
14714 </indexterm>
14716 <synopsis>
14717 <function>xmlagg</function> ( <type>xml</type> ) <returnvalue>xml</returnvalue>
14718 </synopsis>
14720 <para>
14721 The function <function>xmlagg</function> is, unlike the other
14722 functions described here, an aggregate function. It concatenates the
14723 input values to the aggregate function call,
14724 much like <function>xmlconcat</function> does, except that concatenation
14725 occurs across rows rather than across expressions in a single row.
14726 See <xref linkend="functions-aggregate"/> for additional information
14727 about aggregate functions.
14728 </para>
14730 <para>
14731 Example:
14732 <screen><![CDATA[
14733 CREATE TABLE test (y int, x xml);
14734 INSERT INTO test VALUES (1, '<foo>abc</foo>');
14735 INSERT INTO test VALUES (2, '<bar/>');
14736 SELECT xmlagg(x) FROM test;
14737 xmlagg
14738 ----------------------
14739 <foo>abc</foo><bar/>
14740 ]]></screen>
14741 </para>
14743 <para>
14744 To determine the order of the concatenation, an <literal>ORDER BY</literal>
14745 clause may be added to the aggregate call as described in
14746 <xref linkend="syntax-aggregates"/>. For example:
14748 <screen><![CDATA[
14749 SELECT xmlagg(x ORDER BY y DESC) FROM test;
14750 xmlagg
14751 ----------------------
14752 <bar/><foo>abc</foo>
14753 ]]></screen>
14754 </para>
14756 <para>
14757 The following non-standard approach used to be recommended
14758 in previous versions, and may still be useful in specific
14759 cases:
14761 <screen><![CDATA[
14762 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
14763 xmlagg
14764 ----------------------
14765 <bar/><foo>abc</foo>
14766 ]]></screen>
14767 </para>
14768 </sect3>
14769 </sect2>
14771 <sect2 id="functions-xml-predicates">
14772 <title>XML Predicates</title>
14774 <para>
14775 The expressions described in this section check properties
14776 of <type>xml</type> values.
14777 </para>
14779 <sect3 id="functions-producing-xml-is-document">
14780 <title><literal>IS DOCUMENT</literal></title>
14782 <indexterm>
14783 <primary>IS DOCUMENT</primary>
14784 </indexterm>
14786 <synopsis>
14787 <type>xml</type> <literal>IS DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14788 </synopsis>
14790 <para>
14791 The expression <literal>IS DOCUMENT</literal> returns true if the
14792 argument XML value is a proper XML document, false if it is not
14793 (that is, it is a content fragment), or null if the argument is
14794 null. See <xref linkend="datatype-xml"/> about the difference
14795 between documents and content fragments.
14796 </para>
14797 </sect3>
14799 <sect3 id="functions-producing-xml-is-not-document">
14800 <title><literal>IS NOT DOCUMENT</literal></title>
14802 <indexterm>
14803 <primary>IS NOT DOCUMENT</primary>
14804 </indexterm>
14806 <synopsis>
14807 <type>xml</type> <literal>IS NOT DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14808 </synopsis>
14810 <para>
14811 The expression <literal>IS NOT DOCUMENT</literal> returns false if the
14812 argument XML value is a proper XML document, true if it is not (that is,
14813 it is a content fragment), or null if the argument is null.
14814 </para>
14815 </sect3>
14817 <sect3 id="xml-exists">
14818 <title><literal>XMLEXISTS</literal></title>
14820 <indexterm>
14821 <primary>XMLEXISTS</primary>
14822 </indexterm>
14824 <synopsis>
14825 <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>
14826 </synopsis>
14828 <para>
14829 The function <function>xmlexists</function> evaluates an XPath 1.0
14830 expression (the first argument), with the passed XML value as its context
14831 item. The function returns false if the result of that evaluation
14832 yields an empty node-set, true if it yields any other value. The
14833 function returns null if any argument is null. A nonnull value
14834 passed as the context item must be an XML document, not a content
14835 fragment or any non-XML value.
14836 </para>
14838 <para>
14839 Example:
14840 <screen><![CDATA[
14841 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '<towns><town>Toronto</town><town>Ottawa</town></towns>');
14843 xmlexists
14844 ------------
14846 (1 row)
14847 ]]></screen>
14848 </para>
14850 <para>
14851 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
14852 are accepted in <productname>PostgreSQL</productname>, but are ignored,
14853 as discussed in <xref linkend="functions-xml-limits-postgresql"/>.
14854 </para>
14856 <para>
14857 In the SQL standard, the <function>xmlexists</function> function
14858 evaluates an expression in the XML Query language,
14859 but <productname>PostgreSQL</productname> allows only an XPath 1.0
14860 expression, as discussed in
14861 <xref linkend="functions-xml-limits-xpath1"/>.
14862 </para>
14863 </sect3>
14865 <sect3 id="xml-is-well-formed">
14866 <title><literal>xml_is_well_formed</literal></title>
14868 <indexterm>
14869 <primary>xml_is_well_formed</primary>
14870 </indexterm>
14872 <indexterm>
14873 <primary>xml_is_well_formed_document</primary>
14874 </indexterm>
14876 <indexterm>
14877 <primary>xml_is_well_formed_content</primary>
14878 </indexterm>
14880 <synopsis>
14881 <function>xml_is_well_formed</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14882 <function>xml_is_well_formed_document</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14883 <function>xml_is_well_formed_content</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14884 </synopsis>
14886 <para>
14887 These functions check whether a <type>text</type> string represents
14888 well-formed XML, returning a Boolean result.
14889 <function>xml_is_well_formed_document</function> checks for a well-formed
14890 document, while <function>xml_is_well_formed_content</function> checks
14891 for well-formed content. <function>xml_is_well_formed</function> does
14892 the former if the <xref linkend="guc-xmloption"/> configuration
14893 parameter is set to <literal>DOCUMENT</literal>, or the latter if it is set to
14894 <literal>CONTENT</literal>. This means that
14895 <function>xml_is_well_formed</function> is useful for seeing whether
14896 a simple cast to type <type>xml</type> will succeed, whereas the other two
14897 functions are useful for seeing whether the corresponding variants of
14898 <function>XMLPARSE</function> will succeed.
14899 </para>
14901 <para>
14902 Examples:
14904 <screen><![CDATA[
14905 SET xmloption TO DOCUMENT;
14906 SELECT xml_is_well_formed('<>');
14907 xml_is_well_formed
14908 --------------------
14910 (1 row)
14912 SELECT xml_is_well_formed('<abc/>');
14913 xml_is_well_formed
14914 --------------------
14916 (1 row)
14918 SET xmloption TO CONTENT;
14919 SELECT xml_is_well_formed('abc');
14920 xml_is_well_formed
14921 --------------------
14923 (1 row)
14925 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
14926 xml_is_well_formed_document
14927 -----------------------------
14929 (1 row)
14931 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
14932 xml_is_well_formed_document
14933 -----------------------------
14935 (1 row)
14936 ]]></screen>
14938 The last example shows that the checks include whether
14939 namespaces are correctly matched.
14940 </para>
14941 </sect3>
14942 </sect2>
14944 <sect2 id="functions-xml-processing">
14945 <title>Processing XML</title>
14947 <para>
14948 To process values of data type <type>xml</type>, PostgreSQL offers
14949 the functions <function>xpath</function> and
14950 <function>xpath_exists</function>, which evaluate XPath 1.0
14951 expressions, and the <function>XMLTABLE</function>
14952 table function.
14953 </para>
14955 <sect3 id="functions-xml-processing-xpath">
14956 <title><literal>xpath</literal></title>
14958 <indexterm>
14959 <primary>XPath</primary>
14960 </indexterm>
14962 <synopsis>
14963 <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>
14964 </synopsis>
14966 <para>
14967 The function <function>xpath</function> evaluates the XPath 1.0
14968 expression <parameter>xpath</parameter> (given as text)
14969 against the XML value
14970 <parameter>xml</parameter>. It returns an array of XML values
14971 corresponding to the node-set produced by the XPath expression.
14972 If the XPath expression returns a scalar value rather than a node-set,
14973 a single-element array is returned.
14974 </para>
14976 <para>
14977 The second argument must be a well formed XML document. In particular,
14978 it must have a single root node element.
14979 </para>
14981 <para>
14982 The optional third argument of the function is an array of namespace
14983 mappings. This array should be a two-dimensional <type>text</type> array with
14984 the length of the second axis being equal to 2 (i.e., it should be an
14985 array of arrays, each of which consists of exactly 2 elements).
14986 The first element of each array entry is the namespace name (alias), the
14987 second the namespace URI. It is not required that aliases provided in
14988 this array be the same as those being used in the XML document itself (in
14989 other words, both in the XML document and in the <function>xpath</function>
14990 function context, aliases are <emphasis>local</emphasis>).
14991 </para>
14993 <para>
14994 Example:
14995 <screen><![CDATA[
14996 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
14997 ARRAY[ARRAY['my', 'http://example.com']]);
14999 xpath
15000 --------
15001 {test}
15002 (1 row)
15003 ]]></screen>
15004 </para>
15006 <para>
15007 To deal with default (anonymous) namespaces, do something like this:
15008 <screen><![CDATA[
15009 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
15010 ARRAY[ARRAY['mydefns', 'http://example.com']]);
15012 xpath
15013 --------
15014 {test}
15015 (1 row)
15016 ]]></screen>
15017 </para>
15018 </sect3>
15020 <sect3 id="functions-xml-processing-xpath-exists">
15021 <title><literal>xpath_exists</literal></title>
15023 <indexterm>
15024 <primary>xpath_exists</primary>
15025 </indexterm>
15027 <synopsis>
15028 <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>
15029 </synopsis>
15031 <para>
15032 The function <function>xpath_exists</function> is a specialized form
15033 of the <function>xpath</function> function. Instead of returning the
15034 individual XML values that satisfy the XPath 1.0 expression, this function
15035 returns a Boolean indicating whether the query was satisfied or not
15036 (specifically, whether it produced any value other than an empty node-set).
15037 This function is equivalent to the <literal>XMLEXISTS</literal> predicate,
15038 except that it also offers support for a namespace mapping argument.
15039 </para>
15041 <para>
15042 Example:
15043 <screen><![CDATA[
15044 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
15045 ARRAY[ARRAY['my', 'http://example.com']]);
15047 xpath_exists
15048 --------------
15050 (1 row)
15051 ]]></screen>
15052 </para>
15053 </sect3>
15055 <sect3 id="functions-xml-processing-xmltable">
15056 <title><literal>xmltable</literal></title>
15058 <indexterm>
15059 <primary>xmltable</primary>
15060 </indexterm>
15062 <indexterm zone="functions-xml-processing-xmltable">
15063 <primary>table function</primary>
15064 <secondary>XMLTABLE</secondary>
15065 </indexterm>
15067 <synopsis>
15068 <function>XMLTABLE</function> (
15069 <optional> <literal>XMLNAMESPACES</literal> ( <replaceable>namespace_uri</replaceable> <literal>AS</literal> <replaceable>namespace_name</replaceable> <optional>, ...</optional> ), </optional>
15070 <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>
15071 <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>
15072 | <literal>FOR ORDINALITY</literal> }
15073 <optional>, ...</optional>
15074 ) <returnvalue>setof record</returnvalue>
15075 </synopsis>
15077 <para>
15078 The <function>xmltable</function> expression produces a table based
15079 on an XML value, an XPath filter to extract rows, and a
15080 set of column definitions.
15081 Although it syntactically resembles a function, it can only appear
15082 as a table in a query's <literal>FROM</literal> clause.
15083 </para>
15085 <para>
15086 The optional <literal>XMLNAMESPACES</literal> clause gives a
15087 comma-separated list of namespace definitions, where
15088 each <replaceable>namespace_uri</replaceable> is a <type>text</type>
15089 expression and each <replaceable>namespace_name</replaceable> is a simple
15090 identifier. It specifies the XML namespaces used in the document and
15091 their aliases. A default namespace specification is not currently
15092 supported.
15093 </para>
15095 <para>
15096 The required <replaceable>row_expression</replaceable> argument is an
15097 XPath 1.0 expression (given as <type>text</type>) that is evaluated,
15098 passing the XML value <replaceable>document_expression</replaceable> as
15099 its context item, to obtain a set of XML nodes. These nodes are what
15100 <function>xmltable</function> transforms into output rows. No rows
15101 will be produced if the <replaceable>document_expression</replaceable>
15102 is null, nor if the <replaceable>row_expression</replaceable> produces
15103 an empty node-set or any value other than a node-set.
15104 </para>
15106 <para>
15107 <replaceable>document_expression</replaceable> provides the context
15108 item for the <replaceable>row_expression</replaceable>. It must be a
15109 well-formed XML document; fragments/forests are not accepted.
15110 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
15111 are accepted but ignored, as discussed in
15112 <xref linkend="functions-xml-limits-postgresql"/>.
15113 </para>
15115 <para>
15116 In the SQL standard, the <function>xmltable</function> function
15117 evaluates expressions in the XML Query language,
15118 but <productname>PostgreSQL</productname> allows only XPath 1.0
15119 expressions, as discussed in
15120 <xref linkend="functions-xml-limits-xpath1"/>.
15121 </para>
15123 <para>
15124 The required <literal>COLUMNS</literal> clause specifies the
15125 column(s) that will be produced in the output table.
15126 See the syntax summary above for the format.
15127 A name is required for each column, as is a data type
15128 (unless <literal>FOR ORDINALITY</literal> is specified, in which case
15129 type <type>integer</type> is implicit). The path, default and
15130 nullability clauses are optional.
15131 </para>
15133 <para>
15134 A column marked <literal>FOR ORDINALITY</literal> will be populated
15135 with row numbers, starting with 1, in the order of nodes retrieved from
15136 the <replaceable>row_expression</replaceable>'s result node-set.
15137 At most one column may be marked <literal>FOR ORDINALITY</literal>.
15138 </para>
15140 <note>
15141 <para>
15142 XPath 1.0 does not specify an order for nodes in a node-set, so code
15143 that relies on a particular order of the results will be
15144 implementation-dependent. Details can be found in
15145 <xref linkend="xml-xpath-1-specifics"/>.
15146 </para>
15147 </note>
15149 <para>
15150 The <replaceable>column_expression</replaceable> for a column is an
15151 XPath 1.0 expression that is evaluated for each row, with the current
15152 node from the <replaceable>row_expression</replaceable> result as its
15153 context item, to find the value of the column. If
15154 no <replaceable>column_expression</replaceable> is given, then the
15155 column name is used as an implicit path.
15156 </para>
15158 <para>
15159 If a column's XPath expression returns a non-XML value (which is limited
15160 to string, boolean, or double in XPath 1.0) and the column has a
15161 PostgreSQL type other than <type>xml</type>, the column will be set
15162 as if by assigning the value's string representation to the PostgreSQL
15163 type. (If the value is a boolean, its string representation is taken
15164 to be <literal>1</literal> or <literal>0</literal> if the output
15165 column's type category is numeric, otherwise <literal>true</literal> or
15166 <literal>false</literal>.)
15167 </para>
15169 <para>
15170 If a column's XPath expression returns a non-empty set of XML nodes
15171 and the column's PostgreSQL type is <type>xml</type>, the column will
15172 be assigned the expression result exactly, if it is of document or
15173 content form.
15174 <footnote>
15175 <para>
15176 A result containing more than one element node at the top level, or
15177 non-whitespace text outside of an element, is an example of content form.
15178 An XPath result can be of neither form, for example if it returns an
15179 attribute node selected from the element that contains it. Such a result
15180 will be put into content form with each such disallowed node replaced by
15181 its string value, as defined for the XPath 1.0
15182 <function>string</function> function.
15183 </para>
15184 </footnote>
15185 </para>
15187 <para>
15188 A non-XML result assigned to an <type>xml</type> output column produces
15189 content, a single text node with the string value of the result.
15190 An XML result assigned to a column of any other type may not have more than
15191 one node, or an error is raised. If there is exactly one node, the column
15192 will be set as if by assigning the node's string
15193 value (as defined for the XPath 1.0 <function>string</function> function)
15194 to the PostgreSQL type.
15195 </para>
15197 <para>
15198 The string value of an XML element is the concatenation, in document order,
15199 of all text nodes contained in that element and its descendants. The string
15200 value of an element with no descendant text nodes is an
15201 empty string (not <literal>NULL</literal>).
15202 Any <literal>xsi:nil</literal> attributes are ignored.
15203 Note that the whitespace-only <literal>text()</literal> node between two non-text
15204 elements is preserved, and that leading whitespace on a <literal>text()</literal>
15205 node is not flattened.
15206 The XPath 1.0 <function>string</function> function may be consulted for the
15207 rules defining the string value of other XML node types and non-XML values.
15208 </para>
15210 <para>
15211 The conversion rules presented here are not exactly those of the SQL
15212 standard, as discussed in <xref linkend="functions-xml-limits-casts"/>.
15213 </para>
15215 <para>
15216 If the path expression returns an empty node-set
15217 (typically, when it does not match)
15218 for a given row, the column will be set to <literal>NULL</literal>, unless
15219 a <replaceable>default_expression</replaceable> is specified; then the
15220 value resulting from evaluating that expression is used.
15221 </para>
15223 <para>
15224 A <replaceable>default_expression</replaceable>, rather than being
15225 evaluated immediately when <function>xmltable</function> is called,
15226 is evaluated each time a default is needed for the column.
15227 If the expression qualifies as stable or immutable, the repeat
15228 evaluation may be skipped.
15229 This means that you can usefully use volatile functions like
15230 <function>nextval</function> in
15231 <replaceable>default_expression</replaceable>.
15232 </para>
15234 <para>
15235 Columns may be marked <literal>NOT NULL</literal>. If the
15236 <replaceable>column_expression</replaceable> for a <literal>NOT
15237 NULL</literal> column does not match anything and there is
15238 no <literal>DEFAULT</literal> or
15239 the <replaceable>default_expression</replaceable> also evaluates to null,
15240 an error is reported.
15241 </para>
15243 <para>
15244 Examples:
15245 <screen><![CDATA[
15246 CREATE TABLE xmldata AS SELECT
15247 xml $$
15248 <ROWS>
15249 <ROW id="1">
15250 <COUNTRY_ID>AU</COUNTRY_ID>
15251 <COUNTRY_NAME>Australia</COUNTRY_NAME>
15252 </ROW>
15253 <ROW id="5">
15254 <COUNTRY_ID>JP</COUNTRY_ID>
15255 <COUNTRY_NAME>Japan</COUNTRY_NAME>
15256 <PREMIER_NAME>Shinzo Abe</PREMIER_NAME>
15257 <SIZE unit="sq_mi">145935</SIZE>
15258 </ROW>
15259 <ROW id="6">
15260 <COUNTRY_ID>SG</COUNTRY_ID>
15261 <COUNTRY_NAME>Singapore</COUNTRY_NAME>
15262 <SIZE unit="sq_km">697</SIZE>
15263 </ROW>
15264 </ROWS>
15265 $$ AS data;
15267 SELECT xmltable.*
15268 FROM xmldata,
15269 XMLTABLE('//ROWS/ROW'
15270 PASSING data
15271 COLUMNS id int PATH '@id',
15272 ordinality FOR ORDINALITY,
15273 "COUNTRY_NAME" text,
15274 country_id text PATH 'COUNTRY_ID',
15275 size_sq_km float PATH 'SIZE[@unit = "sq_km"]',
15276 size_other text PATH
15277 'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)',
15278 premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified');
15280 id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
15281 ----+------------+--------------+------------+------------+--------------+---------------
15282 1 | 1 | Australia | AU | | | not specified
15283 5 | 2 | Japan | JP | | 145935 sq_mi | Shinzo Abe
15284 6 | 3 | Singapore | SG | 697 | | not specified
15285 ]]></screen>
15287 The following example shows concatenation of multiple text() nodes,
15288 usage of the column name as XPath filter, and the treatment of whitespace,
15289 XML comments and processing instructions:
15291 <screen><![CDATA[
15292 CREATE TABLE xmlelements AS SELECT
15293 xml $$
15294 <root>
15295 <element> Hello<!-- xyxxz -->2a2<?aaaaa?> <!--x--> bbb<x>xxx</x>CC </element>
15296 </root>
15297 $$ AS data;
15299 SELECT xmltable.*
15300 FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
15301 element
15302 -------------------------
15303 Hello2a2 bbbxxxCC
15304 ]]></screen>
15305 </para>
15307 <para>
15308 The following example illustrates how
15309 the <literal>XMLNAMESPACES</literal> clause can be used to specify
15310 a list of namespaces
15311 used in the XML document as well as in the XPath expressions:
15313 <screen><![CDATA[
15314 WITH xmldata(data) AS (VALUES ('
15315 <example xmlns="http://example.com/myns" xmlns:B="http://example.com/b">
15316 <item foo="1" B:bar="2"/>
15317 <item foo="3" B:bar="4"/>
15318 <item foo="4" B:bar="5"/>
15319 </example>'::xml)
15321 SELECT xmltable.*
15322 FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
15323 'http://example.com/b' AS "B"),
15324 '/x:example/x:item'
15325 PASSING (SELECT data FROM xmldata)
15326 COLUMNS foo int PATH '@foo',
15327 bar int PATH '@B:bar');
15328 foo | bar
15329 -----+-----
15330 1 | 2
15331 3 | 4
15332 4 | 5
15333 (3 rows)
15334 ]]></screen>
15335 </para>
15336 </sect3>
15337 </sect2>
15339 <sect2 id="functions-xml-mapping">
15340 <title>Mapping Tables to XML</title>
15342 <indexterm zone="functions-xml-mapping">
15343 <primary>XML export</primary>
15344 </indexterm>
15346 <para>
15347 The following functions map the contents of relational tables to
15348 XML values. They can be thought of as XML export functionality:
15349 <synopsis>
15350 <function>table_to_xml</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15351 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15352 <function>query_to_xml</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15353 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15354 <function>cursor_to_xml</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>count</parameter> <type>integer</type>, <parameter>nulls</parameter> <type>boolean</type>,
15355 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15356 </synopsis>
15357 </para>
15359 <para>
15360 <function>table_to_xml</function> maps the content of the named
15361 table, passed as parameter <parameter>table</parameter>. The
15362 <type>regclass</type> type accepts strings identifying tables using the
15363 usual notation, including optional schema qualification and
15364 double quotes (see <xref linkend="datatype-oid"/> for details).
15365 <function>query_to_xml</function> executes the
15366 query whose text is passed as parameter
15367 <parameter>query</parameter> and maps the result set.
15368 <function>cursor_to_xml</function> fetches the indicated number of
15369 rows from the cursor specified by the parameter
15370 <parameter>cursor</parameter>. This variant is recommended if
15371 large tables have to be mapped, because the result value is built
15372 up in memory by each function.
15373 </para>
15375 <para>
15376 If <parameter>tableforest</parameter> is false, then the resulting
15377 XML document looks like this:
15378 <screen><![CDATA[
15379 <tablename>
15380 <row>
15381 <columnname1>data</columnname1>
15382 <columnname2>data</columnname2>
15383 </row>
15385 <row>
15387 </row>
15390 </tablename>
15391 ]]></screen>
15393 If <parameter>tableforest</parameter> is true, the result is an
15394 XML content fragment that looks like this:
15395 <screen><![CDATA[
15396 <tablename>
15397 <columnname1>data</columnname1>
15398 <columnname2>data</columnname2>
15399 </tablename>
15401 <tablename>
15403 </tablename>
15406 ]]></screen>
15408 If no table name is available, that is, when mapping a query or a
15409 cursor, the string <literal>table</literal> is used in the first
15410 format, <literal>row</literal> in the second format.
15411 </para>
15413 <para>
15414 The choice between these formats is up to the user. The first
15415 format is a proper XML document, which will be important in many
15416 applications. The second format tends to be more useful in the
15417 <function>cursor_to_xml</function> function if the result values are to be
15418 reassembled into one document later on. The functions for
15419 producing XML content discussed above, in particular
15420 <function>xmlelement</function>, can be used to alter the results
15421 to taste.
15422 </para>
15424 <para>
15425 The data values are mapped in the same way as described for the
15426 function <function>xmlelement</function> above.
15427 </para>
15429 <para>
15430 The parameter <parameter>nulls</parameter> determines whether null
15431 values should be included in the output. If true, null values in
15432 columns are represented as:
15433 <screen><![CDATA[
15434 <columnname xsi:nil="true"/>
15435 ]]></screen>
15436 where <literal>xsi</literal> is the XML namespace prefix for XML
15437 Schema Instance. An appropriate namespace declaration will be
15438 added to the result value. If false, columns containing null
15439 values are simply omitted from the output.
15440 </para>
15442 <para>
15443 The parameter <parameter>targetns</parameter> specifies the
15444 desired XML namespace of the result. If no particular namespace
15445 is wanted, an empty string should be passed.
15446 </para>
15448 <para>
15449 The following functions return XML Schema documents describing the
15450 mappings performed by the corresponding functions above:
15451 <synopsis>
15452 <function>table_to_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15453 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15454 <function>query_to_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15455 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15456 <function>cursor_to_xmlschema</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>nulls</parameter> <type>boolean</type>,
15457 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15458 </synopsis>
15459 It is essential that the same parameters are passed in order to
15460 obtain matching XML data mappings and XML Schema documents.
15461 </para>
15463 <para>
15464 The following functions produce XML data mappings and the
15465 corresponding XML Schema in one document (or forest), linked
15466 together. They can be useful where self-contained and
15467 self-describing results are wanted:
15468 <synopsis>
15469 <function>table_to_xml_and_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
15470 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15471 <function>query_to_xml_and_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
15472 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15473 </synopsis>
15474 </para>
15476 <para>
15477 In addition, the following functions are available to produce
15478 analogous mappings of entire schemas or the entire current
15479 database:
15480 <synopsis>
15481 <function>schema_to_xml</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15482 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15483 <function>schema_to_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15484 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15485 <function>schema_to_xml_and_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
15486 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15488 <function>database_to_xml</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15489 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15490 <function>database_to_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15491 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15492 <function>database_to_xml_and_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
15493 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
15494 </synopsis>
15496 These functions ignore tables that are not readable by the current user.
15497 The database-wide functions additionally ignore schemas that the current
15498 user does not have <literal>USAGE</literal> (lookup) privilege for.
15499 </para>
15501 <para>
15502 Note that these potentially produce a lot of data, which needs to
15503 be built up in memory. When requesting content mappings of large
15504 schemas or databases, it might be worthwhile to consider mapping the
15505 tables separately instead, possibly even through a cursor.
15506 </para>
15508 <para>
15509 The result of a schema content mapping looks like this:
15511 <screen><![CDATA[
15512 <schemaname>
15514 table1-mapping
15516 table2-mapping
15520 </schemaname>]]></screen>
15522 where the format of a table mapping depends on the
15523 <parameter>tableforest</parameter> parameter as explained above.
15524 </para>
15526 <para>
15527 The result of a database content mapping looks like this:
15529 <screen><![CDATA[
15530 <dbname>
15532 <schema1name>
15534 </schema1name>
15536 <schema2name>
15538 </schema2name>
15542 </dbname>]]></screen>
15544 where the schema mapping is as above.
15545 </para>
15547 <para>
15548 As an example of using the output produced by these functions,
15549 <xref linkend="xslt-xml-html"/> shows an XSLT stylesheet that
15550 converts the output of
15551 <function>table_to_xml_and_xmlschema</function> to an HTML
15552 document containing a tabular rendition of the table data. In a
15553 similar manner, the results from these functions can be
15554 converted into other XML-based formats.
15555 </para>
15557 <example id="xslt-xml-html">
15558 <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
15559 <programlisting><![CDATA[
15560 <?xml version="1.0"?>
15561 <xsl:stylesheet version="1.0"
15562 xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
15563 xmlns:xsd="http://www.w3.org/2001/XMLSchema"
15564 xmlns="http://www.w3.org/1999/xhtml"
15567 <xsl:output method="xml"
15568 doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
15569 doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
15570 indent="yes"/>
15572 <xsl:template match="/*">
15573 <xsl:variable name="schema" select="//xsd:schema"/>
15574 <xsl:variable name="tabletypename"
15575 select="$schema/xsd:element[@name=name(current())]/@type"/>
15576 <xsl:variable name="rowtypename"
15577 select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
15579 <html>
15580 <head>
15581 <title><xsl:value-of select="name(current())"/></title>
15582 </head>
15583 <body>
15584 <table>
15585 <tr>
15586 <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
15587 <th><xsl:value-of select="."/></th>
15588 </xsl:for-each>
15589 </tr>
15591 <xsl:for-each select="row">
15592 <tr>
15593 <xsl:for-each select="*">
15594 <td><xsl:value-of select="."/></td>
15595 </xsl:for-each>
15596 </tr>
15597 </xsl:for-each>
15598 </table>
15599 </body>
15600 </html>
15601 </xsl:template>
15603 </xsl:stylesheet>
15604 ]]></programlisting>
15605 </example>
15606 </sect2>
15607 </sect1>
15609 <sect1 id="functions-json">
15610 <title>JSON Functions and Operators</title>
15612 <indexterm zone="functions-json">
15613 <primary>JSON</primary>
15614 <secondary>functions and operators</secondary>
15615 </indexterm>
15616 <indexterm zone="functions-json">
15617 <primary>SQL/JSON</primary>
15618 <secondary>functions and expressions</secondary>
15619 </indexterm>
15621 <para>
15622 This section describes:
15624 <itemizedlist>
15625 <listitem>
15626 <para>
15627 functions and operators for processing and creating JSON data
15628 </para>
15629 </listitem>
15630 <listitem>
15631 <para>
15632 the SQL/JSON path language
15633 </para>
15634 </listitem>
15635 <listitem>
15636 <para>
15637 the SQL/JSON query functions
15638 </para>
15639 </listitem>
15640 </itemizedlist>
15641 </para>
15643 <para>
15644 To provide native support for JSON data types within the SQL environment,
15645 <productname>PostgreSQL</productname> implements the
15646 <firstterm>SQL/JSON data model</firstterm>.
15647 This model comprises sequences of items. Each item can hold SQL scalar
15648 values, with an additional SQL/JSON null value, and composite data structures
15649 that use JSON arrays and objects. The model is a formalization of the implied
15650 data model in the JSON specification
15651 <ulink url="https://datatracker.ietf.org/doc/html/rfc7159">RFC 7159</ulink>.
15652 </para>
15654 <para>
15655 SQL/JSON allows you to handle JSON data alongside regular SQL data,
15656 with transaction support, including:
15658 <itemizedlist>
15659 <listitem>
15660 <para>
15661 Uploading JSON data into the database and storing it in
15662 regular SQL columns as character or binary strings.
15663 </para>
15664 </listitem>
15665 <listitem>
15666 <para>
15667 Generating JSON objects and arrays from relational data.
15668 </para>
15669 </listitem>
15670 <listitem>
15671 <para>
15672 Querying JSON data using SQL/JSON query functions and
15673 SQL/JSON path language expressions.
15674 </para>
15675 </listitem>
15676 </itemizedlist>
15677 </para>
15679 <para>
15680 To learn more about the SQL/JSON standard, see
15681 <xref linkend="sqltr-19075-6"/>. For details on JSON types
15682 supported in <productname>PostgreSQL</productname>,
15683 see <xref linkend="datatype-json"/>.
15684 </para>
15686 <sect2 id="functions-json-processing">
15687 <title>Processing and Creating JSON Data</title>
15689 <para>
15690 <xref linkend="functions-json-op-table"/> shows the operators that
15691 are available for use with JSON data types (see <xref
15692 linkend="datatype-json"/>).
15693 In addition, the usual comparison operators shown in <xref
15694 linkend="functions-comparison-op-table"/> are available for
15695 <type>jsonb</type>, though not for <type>json</type>. The comparison
15696 operators follow the ordering rules for B-tree operations outlined in
15697 <xref linkend="json-indexing"/>.
15698 See also <xref linkend="functions-aggregate"/> for the aggregate
15699 function <function>json_agg</function> which aggregates record
15700 values as JSON, the aggregate function
15701 <function>json_object_agg</function> which aggregates pairs of values
15702 into a JSON object, and their <type>jsonb</type> equivalents,
15703 <function>jsonb_agg</function> and <function>jsonb_object_agg</function>.
15704 </para>
15706 <table id="functions-json-op-table">
15707 <title><type>json</type> and <type>jsonb</type> Operators</title>
15708 <tgroup cols="1">
15709 <thead>
15710 <row>
15711 <entry role="func_table_entry"><para role="func_signature">
15712 Operator
15713 </para>
15714 <para>
15715 Description
15716 </para>
15717 <para>
15718 Example(s)
15719 </para></entry>
15720 </row>
15721 </thead>
15723 <tbody>
15724 <row>
15725 <entry role="func_table_entry"><para role="func_signature">
15726 <type>json</type> <literal>-&gt;</literal> <type>integer</type>
15727 <returnvalue>json</returnvalue>
15728 </para>
15729 <para role="func_signature">
15730 <type>jsonb</type> <literal>-&gt;</literal> <type>integer</type>
15731 <returnvalue>jsonb</returnvalue>
15732 </para>
15733 <para>
15734 Extracts <parameter>n</parameter>'th element of JSON array
15735 (array elements are indexed from zero, but negative integers count
15736 from the end).
15737 </para>
15738 <para>
15739 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; 2</literal>
15740 <returnvalue>{"c":"baz"}</returnvalue>
15741 </para>
15742 <para>
15743 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; -3</literal>
15744 <returnvalue>{"a":"foo"}</returnvalue>
15745 </para></entry>
15746 </row>
15748 <row>
15749 <entry role="func_table_entry"><para role="func_signature">
15750 <type>json</type> <literal>-&gt;</literal> <type>text</type>
15751 <returnvalue>json</returnvalue>
15752 </para>
15753 <para role="func_signature">
15754 <type>jsonb</type> <literal>-&gt;</literal> <type>text</type>
15755 <returnvalue>jsonb</returnvalue>
15756 </para>
15757 <para>
15758 Extracts JSON object field with the given key.
15759 </para>
15760 <para>
15761 <literal>'{"a": {"b":"foo"}}'::json -&gt; 'a'</literal>
15762 <returnvalue>{"b":"foo"}</returnvalue>
15763 </para></entry>
15764 </row>
15766 <row>
15767 <entry role="func_table_entry"><para role="func_signature">
15768 <type>json</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15769 <returnvalue>text</returnvalue>
15770 </para>
15771 <para role="func_signature">
15772 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15773 <returnvalue>text</returnvalue>
15774 </para>
15775 <para>
15776 Extracts <parameter>n</parameter>'th element of JSON array,
15777 as <type>text</type>.
15778 </para>
15779 <para>
15780 <literal>'[1,2,3]'::json -&gt;&gt; 2</literal>
15781 <returnvalue>3</returnvalue>
15782 </para></entry>
15783 </row>
15785 <row>
15786 <entry role="func_table_entry"><para role="func_signature">
15787 <type>json</type> <literal>-&gt;&gt;</literal> <type>text</type>
15788 <returnvalue>text</returnvalue>
15789 </para>
15790 <para role="func_signature">
15791 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>text</type>
15792 <returnvalue>text</returnvalue>
15793 </para>
15794 <para>
15795 Extracts JSON object field with the given key, as <type>text</type>.
15796 </para>
15797 <para>
15798 <literal>'{"a":1,"b":2}'::json -&gt;&gt; 'b'</literal>
15799 <returnvalue>2</returnvalue>
15800 </para></entry>
15801 </row>
15803 <row>
15804 <entry role="func_table_entry"><para role="func_signature">
15805 <type>json</type> <literal>#&gt;</literal> <type>text[]</type>
15806 <returnvalue>json</returnvalue>
15807 </para>
15808 <para role="func_signature">
15809 <type>jsonb</type> <literal>#&gt;</literal> <type>text[]</type>
15810 <returnvalue>jsonb</returnvalue>
15811 </para>
15812 <para>
15813 Extracts JSON sub-object at the specified path, where path elements
15814 can be either field keys or array indexes.
15815 </para>
15816 <para>
15817 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt; '{a,b,1}'</literal>
15818 <returnvalue>"bar"</returnvalue>
15819 </para></entry>
15820 </row>
15822 <row>
15823 <entry role="func_table_entry"><para role="func_signature">
15824 <type>json</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15825 <returnvalue>text</returnvalue>
15826 </para>
15827 <para role="func_signature">
15828 <type>jsonb</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15829 <returnvalue>text</returnvalue>
15830 </para>
15831 <para>
15832 Extracts JSON sub-object at the specified path as <type>text</type>.
15833 </para>
15834 <para>
15835 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt;&gt; '{a,b,1}'</literal>
15836 <returnvalue>bar</returnvalue>
15837 </para></entry>
15838 </row>
15839 </tbody>
15840 </tgroup>
15841 </table>
15843 <note>
15844 <para>
15845 The field/element/path extraction operators return NULL, rather than
15846 failing, if the JSON input does not have the right structure to match
15847 the request; for example if no such key or array element exists.
15848 </para>
15849 </note>
15851 <para>
15852 Some further operators exist only for <type>jsonb</type>, as shown
15853 in <xref linkend="functions-jsonb-op-table"/>.
15854 <xref linkend="json-indexing"/>
15855 describes how these operators can be used to effectively search indexed
15856 <type>jsonb</type> data.
15857 </para>
15859 <table id="functions-jsonb-op-table">
15860 <title>Additional <type>jsonb</type> Operators</title>
15861 <tgroup cols="1">
15862 <thead>
15863 <row>
15864 <entry role="func_table_entry"><para role="func_signature">
15865 Operator
15866 </para>
15867 <para>
15868 Description
15869 </para>
15870 <para>
15871 Example(s)
15872 </para></entry>
15873 </row>
15874 </thead>
15876 <tbody>
15877 <row>
15878 <entry role="func_table_entry"><para role="func_signature">
15879 <type>jsonb</type> <literal>@&gt;</literal> <type>jsonb</type>
15880 <returnvalue>boolean</returnvalue>
15881 </para>
15882 <para>
15883 Does the first JSON value contain the second?
15884 (See <xref linkend="json-containment"/> for details about containment.)
15885 </para>
15886 <para>
15887 <literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal>
15888 <returnvalue>t</returnvalue>
15889 </para></entry>
15890 </row>
15892 <row>
15893 <entry role="func_table_entry"><para role="func_signature">
15894 <type>jsonb</type> <literal>&lt;@</literal> <type>jsonb</type>
15895 <returnvalue>boolean</returnvalue>
15896 </para>
15897 <para>
15898 Is the first JSON value contained in the second?
15899 </para>
15900 <para>
15901 <literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal>
15902 <returnvalue>t</returnvalue>
15903 </para></entry>
15904 </row>
15906 <row>
15907 <entry role="func_table_entry"><para role="func_signature">
15908 <type>jsonb</type> <literal>?</literal> <type>text</type>
15909 <returnvalue>boolean</returnvalue>
15910 </para>
15911 <para>
15912 Does the text string exist as a top-level key or array element within
15913 the JSON value?
15914 </para>
15915 <para>
15916 <literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal>
15917 <returnvalue>t</returnvalue>
15918 </para>
15919 <para>
15920 <literal>'["a", "b", "c"]'::jsonb ? 'b'</literal>
15921 <returnvalue>t</returnvalue>
15922 </para></entry>
15923 </row>
15925 <row>
15926 <entry role="func_table_entry"><para role="func_signature">
15927 <type>jsonb</type> <literal>?|</literal> <type>text[]</type>
15928 <returnvalue>boolean</returnvalue>
15929 </para>
15930 <para>
15931 Do any of the strings in the text array exist as top-level keys or
15932 array elements?
15933 </para>
15934 <para>
15935 <literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'd']</literal>
15936 <returnvalue>t</returnvalue>
15937 </para></entry>
15938 </row>
15940 <row>
15941 <entry role="func_table_entry"><para role="func_signature">
15942 <type>jsonb</type> <literal>?&amp;</literal> <type>text[]</type>
15943 <returnvalue>boolean</returnvalue>
15944 </para>
15945 <para>
15946 Do all of the strings in the text array exist as top-level keys or
15947 array elements?
15948 </para>
15949 <para>
15950 <literal>'["a", "b", "c"]'::jsonb ?&amp; array['a', 'b']</literal>
15951 <returnvalue>t</returnvalue>
15952 </para></entry>
15953 </row>
15955 <row>
15956 <entry role="func_table_entry"><para role="func_signature">
15957 <type>jsonb</type> <literal>||</literal> <type>jsonb</type>
15958 <returnvalue>jsonb</returnvalue>
15959 </para>
15960 <para>
15961 Concatenates two <type>jsonb</type> values.
15962 Concatenating two arrays generates an array containing all the
15963 elements of each input. Concatenating two objects generates an
15964 object containing the union of their
15965 keys, taking the second object's value when there are duplicate keys.
15966 All other cases are treated by converting a non-array input into a
15967 single-element array, and then proceeding as for two arrays.
15968 Does not operate recursively: only the top-level array or object
15969 structure is merged.
15970 </para>
15971 <para>
15972 <literal>'["a", "b"]'::jsonb || '["a", "d"]'::jsonb</literal>
15973 <returnvalue>["a", "b", "a", "d"]</returnvalue>
15974 </para>
15975 <para>
15976 <literal>'{"a": "b"}'::jsonb || '{"c": "d"}'::jsonb</literal>
15977 <returnvalue>{"a": "b", "c": "d"}</returnvalue>
15978 </para>
15979 <para>
15980 <literal>'[1, 2]'::jsonb || '3'::jsonb</literal>
15981 <returnvalue>[1, 2, 3]</returnvalue>
15982 </para>
15983 <para>
15984 <literal>'{"a": "b"}'::jsonb || '42'::jsonb</literal>
15985 <returnvalue>[{"a": "b"}, 42]</returnvalue>
15986 </para>
15987 <para>
15988 To append an array to another array as a single entry, wrap it
15989 in an additional layer of array, for example:
15990 </para>
15991 <para>
15992 <literal>'[1, 2]'::jsonb || jsonb_build_array('[3, 4]'::jsonb)</literal>
15993 <returnvalue>[1, 2, [3, 4]]</returnvalue>
15994 </para></entry>
15995 </row>
15997 <row>
15998 <entry role="func_table_entry"><para role="func_signature">
15999 <type>jsonb</type> <literal>-</literal> <type>text</type>
16000 <returnvalue>jsonb</returnvalue>
16001 </para>
16002 <para>
16003 Deletes a key (and its value) from a JSON object, or matching string
16004 value(s) from a JSON array.
16005 </para>
16006 <para>
16007 <literal>'{"a": "b", "c": "d"}'::jsonb - 'a'</literal>
16008 <returnvalue>{"c": "d"}</returnvalue>
16009 </para>
16010 <para>
16011 <literal>'["a", "b", "c", "b"]'::jsonb - 'b'</literal>
16012 <returnvalue>["a", "c"]</returnvalue>
16013 </para></entry>
16014 </row>
16016 <row>
16017 <entry role="func_table_entry"><para role="func_signature">
16018 <type>jsonb</type> <literal>-</literal> <type>text[]</type>
16019 <returnvalue>jsonb</returnvalue>
16020 </para>
16021 <para>
16022 Deletes all matching keys or array elements from the left operand.
16023 </para>
16024 <para>
16025 <literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[]</literal>
16026 <returnvalue>{}</returnvalue>
16027 </para></entry>
16028 </row>
16030 <row>
16031 <entry role="func_table_entry"><para role="func_signature">
16032 <type>jsonb</type> <literal>-</literal> <type>integer</type>
16033 <returnvalue>jsonb</returnvalue>
16034 </para>
16035 <para>
16036 Deletes the array element with specified index (negative
16037 integers count from the end). Throws an error if JSON value
16038 is not an array.
16039 </para>
16040 <para>
16041 <literal>'["a", "b"]'::jsonb - 1 </literal>
16042 <returnvalue>["a"]</returnvalue>
16043 </para></entry>
16044 </row>
16046 <row>
16047 <entry role="func_table_entry"><para role="func_signature">
16048 <type>jsonb</type> <literal>#-</literal> <type>text[]</type>
16049 <returnvalue>jsonb</returnvalue>
16050 </para>
16051 <para>
16052 Deletes the field or array element at the specified path, where path
16053 elements can be either field keys or array indexes.
16054 </para>
16055 <para>
16056 <literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal>
16057 <returnvalue>["a", {}]</returnvalue>
16058 </para></entry>
16059 </row>
16061 <row>
16062 <entry role="func_table_entry"><para role="func_signature">
16063 <type>jsonb</type> <literal>@?</literal> <type>jsonpath</type>
16064 <returnvalue>boolean</returnvalue>
16065 </para>
16066 <para>
16067 Does JSON path return any item for the specified JSON value?
16068 (This is useful only with SQL-standard JSON path expressions, not
16069 <link linkend="functions-sqljson-check-expressions">predicate check
16070 expressions</link>, since those always return a value.)
16071 </para>
16072 <para>
16073 <literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal>
16074 <returnvalue>t</returnvalue>
16075 </para></entry>
16076 </row>
16078 <row>
16079 <entry role="func_table_entry"><para role="func_signature">
16080 <type>jsonb</type> <literal>@@</literal> <type>jsonpath</type>
16081 <returnvalue>boolean</returnvalue>
16082 </para>
16083 <para>
16084 Returns the result of a JSON path predicate check for the
16085 specified JSON value.
16086 (This is useful only
16087 with <link linkend="functions-sqljson-check-expressions">predicate
16088 check expressions</link>, not SQL-standard JSON path expressions,
16089 since it will return <literal>NULL</literal> if the path result is
16090 not a single boolean value.)
16091 </para>
16092 <para>
16093 <literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal>
16094 <returnvalue>t</returnvalue>
16095 </para></entry>
16096 </row>
16097 </tbody>
16098 </tgroup>
16099 </table>
16101 <note>
16102 <para>
16103 The <type>jsonpath</type> operators <literal>@?</literal>
16104 and <literal>@@</literal> suppress the following errors: missing object
16105 field or array element, unexpected JSON item type, datetime and numeric
16106 errors. The <type>jsonpath</type>-related functions described below can
16107 also be told to suppress these types of errors. This behavior might be
16108 helpful when searching JSON document collections of varying structure.
16109 </para>
16110 </note>
16112 <para>
16113 <xref linkend="functions-json-creation-table"/> shows the functions that are
16114 available for constructing <type>json</type> and <type>jsonb</type> values.
16115 Some functions in this table have a <literal>RETURNING</literal> clause,
16116 which specifies the data type returned. It must be one of <type>json</type>,
16117 <type>jsonb</type>, <type>bytea</type>, a character string type (<type>text</type>,
16118 <type>char</type>, or <type>varchar</type>), or a type
16119 that can be cast to <type>json</type>.
16120 By default, the <type>json</type> type is returned.
16121 </para>
16123 <table id="functions-json-creation-table">
16124 <title>JSON Creation Functions</title>
16125 <tgroup cols="1">
16126 <thead>
16127 <row>
16128 <entry role="func_table_entry"><para role="func_signature">
16129 Function
16130 </para>
16131 <para>
16132 Description
16133 </para>
16134 <para>
16135 Example(s)
16136 </para></entry>
16137 </row>
16138 </thead>
16140 <tbody>
16141 <row>
16142 <entry role="func_table_entry"><para role="func_signature">
16143 <indexterm>
16144 <primary>to_json</primary>
16145 </indexterm>
16146 <function>to_json</function> ( <type>anyelement</type> )
16147 <returnvalue>json</returnvalue>
16148 </para>
16149 <para role="func_signature">
16150 <indexterm>
16151 <primary>to_jsonb</primary>
16152 </indexterm>
16153 <function>to_jsonb</function> ( <type>anyelement</type> )
16154 <returnvalue>jsonb</returnvalue>
16155 </para>
16156 <para>
16157 Converts any SQL value to <type>json</type> or <type>jsonb</type>.
16158 Arrays and composites are converted recursively to arrays and
16159 objects (multidimensional arrays become arrays of arrays in JSON).
16160 Otherwise, if there is a cast from the SQL data type
16161 to <type>json</type>, the cast function will be used to perform the
16162 conversion;<footnote>
16163 <para>
16164 For example, the <xref linkend="hstore"/> extension has a cast
16165 from <type>hstore</type> to <type>json</type>, so that
16166 <type>hstore</type> values converted via the JSON creation functions
16167 will be represented as JSON objects, not as primitive string values.
16168 </para>
16169 </footnote>
16170 otherwise, a scalar JSON value is produced. For any scalar other than
16171 a number, a Boolean, or a null value, the text representation will be
16172 used, with escaping as necessary to make it a valid JSON string value.
16173 </para>
16174 <para>
16175 <literal>to_json('Fred said "Hi."'::text)</literal>
16176 <returnvalue>"Fred said \"Hi.\""</returnvalue>
16177 </para>
16178 <para>
16179 <literal>to_jsonb(row(42, 'Fred said "Hi."'::text))</literal>
16180 <returnvalue>{"f1": 42, "f2": "Fred said \"Hi.\""}</returnvalue>
16181 </para></entry>
16182 </row>
16184 <row>
16185 <entry role="func_table_entry"><para role="func_signature">
16186 <indexterm>
16187 <primary>array_to_json</primary>
16188 </indexterm>
16189 <function>array_to_json</function> ( <type>anyarray</type> <optional>, <type>boolean</type> </optional> )
16190 <returnvalue>json</returnvalue>
16191 </para>
16192 <para>
16193 Converts an SQL array to a JSON array. The behavior is the same
16194 as <function>to_json</function> except that line feeds will be added
16195 between top-level array elements if the optional boolean parameter is
16196 true.
16197 </para>
16198 <para>
16199 <literal>array_to_json('{{1,5},{99,100}}'::int[])</literal>
16200 <returnvalue>[[1,5],[99,100]]</returnvalue>
16201 </para></entry>
16202 </row>
16204 <row>
16205 <!--
16206 Note that this is barely legible in the output; it looks like a
16207 salad of braces and brackets. It would be better to split it out
16208 in multiple lines, but that's surprisingly hard to do in a way that
16209 matches in HTML and PDF output. Other standard SQL/JSON functions
16210 have the same problem.
16212 <entry role="func_table_entry"><para role="func_signature">
16213 <indexterm><primary>json_array</primary></indexterm>
16214 <function>json_array</function> (
16215 <optional> { <replaceable>value_expression</replaceable> <optional> <literal>FORMAT JSON</literal> </optional> } <optional>, ...</optional> </optional>
16216 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
16217 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
16218 </para>
16219 <para role="func_signature">
16220 <function>json_array</function> (
16221 <optional> <replaceable>query_expression</replaceable> </optional>
16222 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
16223 </para>
16224 <para>
16225 Constructs a JSON array from either a series of
16226 <replaceable>value_expression</replaceable> parameters or from the results
16227 of <replaceable>query_expression</replaceable>,
16228 which must be a SELECT query returning a single column. If
16229 <literal>ABSENT ON NULL</literal> is specified, NULL values are ignored.
16230 This is always the case if a
16231 <replaceable>query_expression</replaceable> is used.
16232 </para>
16233 <para>
16234 <literal>json_array(1,true,json '{"a":null}')</literal>
16235 <returnvalue>[1, true, {"a":null}]</returnvalue>
16236 </para>
16237 <para>
16238 <literal>json_array(SELECT * FROM (VALUES(1),(2)) t)</literal>
16239 <returnvalue>[1, 2]</returnvalue>
16240 </para></entry>
16241 </row>
16243 <row>
16244 <entry role="func_table_entry"><para role="func_signature">
16245 <indexterm>
16246 <primary>row_to_json</primary>
16247 </indexterm>
16248 <function>row_to_json</function> ( <type>record</type> <optional>, <type>boolean</type> </optional> )
16249 <returnvalue>json</returnvalue>
16250 </para>
16251 <para>
16252 Converts an SQL composite value to a JSON object. The behavior is the
16253 same as <function>to_json</function> except that line feeds will be
16254 added between top-level elements if the optional boolean parameter is
16255 true.
16256 </para>
16257 <para>
16258 <literal>row_to_json(row(1,'foo'))</literal>
16259 <returnvalue>{"f1":1,"f2":"foo"}</returnvalue>
16260 </para></entry>
16261 </row>
16263 <row>
16264 <entry role="func_table_entry"><para role="func_signature">
16265 <indexterm>
16266 <primary>json_build_array</primary>
16267 </indexterm>
16268 <function>json_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16269 <returnvalue>json</returnvalue>
16270 </para>
16271 <para role="func_signature">
16272 <indexterm>
16273 <primary>jsonb_build_array</primary>
16274 </indexterm>
16275 <function>jsonb_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16276 <returnvalue>jsonb</returnvalue>
16277 </para>
16278 <para>
16279 Builds a possibly-heterogeneously-typed JSON array out of a variadic
16280 argument list. Each argument is converted as
16281 per <function>to_json</function> or <function>to_jsonb</function>.
16282 </para>
16283 <para>
16284 <literal>json_build_array(1, 2, 'foo', 4, 5)</literal>
16285 <returnvalue>[1, 2, "foo", 4, 5]</returnvalue>
16286 </para></entry>
16287 </row>
16289 <row>
16290 <entry role="func_table_entry"><para role="func_signature">
16291 <indexterm>
16292 <primary>json_build_object</primary>
16293 </indexterm>
16294 <function>json_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16295 <returnvalue>json</returnvalue>
16296 </para>
16297 <para role="func_signature">
16298 <indexterm>
16299 <primary>jsonb_build_object</primary>
16300 </indexterm>
16301 <function>jsonb_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
16302 <returnvalue>jsonb</returnvalue>
16303 </para>
16304 <para>
16305 Builds a JSON object out of a variadic argument list. By convention,
16306 the argument list consists of alternating keys and values. Key
16307 arguments are coerced to text; value arguments are converted as
16308 per <function>to_json</function> or <function>to_jsonb</function>.
16309 </para>
16310 <para>
16311 <literal>json_build_object('foo', 1, 2, row(3,'bar'))</literal>
16312 <returnvalue>{"foo" : 1, "2" : {"f1":3,"f2":"bar"}}</returnvalue>
16313 </para></entry>
16314 </row>
16316 <row>
16317 <entry role="func_table_entry"><para role="func_signature">
16318 <indexterm><primary>json_object</primary></indexterm>
16319 <function>json_object</function> (
16320 <optional> { <replaceable>key_expression</replaceable> { <literal>VALUE</literal> | ':' }
16321 <replaceable>value_expression</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> }<optional>, ...</optional> </optional>
16322 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
16323 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
16324 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
16325 </para>
16326 <para>
16327 Constructs a JSON object of all the key/value pairs given,
16328 or an empty object if none are given.
16329 <replaceable>key_expression</replaceable> is a scalar expression
16330 defining the <acronym>JSON</acronym> key, which is
16331 converted to the <type>text</type> type.
16332 It cannot be <literal>NULL</literal> nor can it
16333 belong to a type that has a cast to the <type>json</type> type.
16334 If <literal>WITH UNIQUE KEYS</literal> is specified, there must not
16335 be any duplicate <replaceable>key_expression</replaceable>.
16336 Any pair for which the <replaceable>value_expression</replaceable>
16337 evaluates to <literal>NULL</literal> is omitted from the output
16338 if <literal>ABSENT ON NULL</literal> is specified;
16339 if <literal>NULL ON NULL</literal> is specified or the clause
16340 omitted, the key is included with value <literal>NULL</literal>.
16341 </para>
16342 <para>
16343 <literal>json_object('code' VALUE 'P123', 'title': 'Jaws')</literal>
16344 <returnvalue>{"code" : "P123", "title" : "Jaws"}</returnvalue>
16345 </para></entry>
16346 </row>
16348 <row>
16349 <entry role="func_table_entry"><para role="func_signature">
16350 <indexterm>
16351 <primary>json_object</primary>
16352 </indexterm>
16353 <function>json_object</function> ( <type>text[]</type> )
16354 <returnvalue>json</returnvalue>
16355 </para>
16356 <para role="func_signature">
16357 <indexterm>
16358 <primary>jsonb_object</primary>
16359 </indexterm>
16360 <function>jsonb_object</function> ( <type>text[]</type> )
16361 <returnvalue>jsonb</returnvalue>
16362 </para>
16363 <para>
16364 Builds a JSON object out of a text array. The array must have either
16365 exactly one dimension with an even number of members, in which case
16366 they are taken as alternating key/value pairs, or two dimensions
16367 such that each inner array has exactly two elements, which
16368 are taken as a key/value pair. All values are converted to JSON
16369 strings.
16370 </para>
16371 <para>
16372 <literal>json_object('{a, 1, b, "def", c, 3.5}')</literal>
16373 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
16374 </para>
16375 <para><literal>json_object('{{a, 1}, {b, "def"}, {c, 3.5}}')</literal>
16376 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
16377 </para></entry>
16378 </row>
16380 <row>
16381 <entry role="func_table_entry"><para role="func_signature">
16382 <function>json_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
16383 <returnvalue>json</returnvalue>
16384 </para>
16385 <para role="func_signature">
16386 <function>jsonb_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
16387 <returnvalue>jsonb</returnvalue>
16388 </para>
16389 <para>
16390 This form of <function>json_object</function> takes keys and values
16391 pairwise from separate text arrays. Otherwise it is identical to
16392 the one-argument form.
16393 </para>
16394 <para>
16395 <literal>json_object('{a,b}', '{1,2}')</literal>
16396 <returnvalue>{"a": "1", "b": "2"}</returnvalue>
16397 </para></entry>
16398 </row>
16399 <row>
16400 <entry role="func_table_entry">
16401 <para role="func_signature">
16402 <indexterm><primary>json constructor</primary></indexterm>
16403 <function>json</function> (
16404 <replaceable>expression</replaceable>
16405 <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional></optional>
16406 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional></optional> )
16407 <returnvalue>json</returnvalue>
16408 </para>
16409 <para>
16410 Converts a given expression specified as <type>text</type> or
16411 <type>bytea</type> string (in UTF8 encoding) into a JSON
16412 value. If <replaceable>expression</replaceable> is NULL, an
16413 <acronym>SQL</acronym> null value is returned.
16414 If <literal>WITH UNIQUE</literal> is specified, the
16415 <replaceable>expression</replaceable> must not contain any duplicate
16416 object keys.
16417 </para>
16418 <para>
16419 <literal>json('{"a":123, "b":[true,"foo"], "a":"bar"}')</literal>
16420 <returnvalue>{"a":123, "b":[true,"foo"], "a":"bar"}</returnvalue>
16421 </para>
16422 </entry>
16423 </row>
16424 <row>
16425 <entry role="func_table_entry">
16426 <para role="func_signature">
16427 <indexterm><primary>json_scalar</primary></indexterm>
16428 <function>json_scalar</function> ( <replaceable>expression</replaceable> )
16429 </para>
16430 <para>
16431 Converts a given SQL scalar value into a JSON scalar value.
16432 If the input is NULL, an <acronym>SQL</acronym> null is returned. If
16433 the input is number or a boolean value, a corresponding JSON number
16434 or boolean value is returned. For any other value, a JSON string is
16435 returned.
16436 </para>
16437 <para>
16438 <literal>json_scalar(123.45)</literal>
16439 <returnvalue>123.45</returnvalue>
16440 </para>
16441 <para>
16442 <literal>json_scalar(CURRENT_TIMESTAMP)</literal>
16443 <returnvalue>"2022-05-10T10:51:04.62128-04:00"</returnvalue>
16444 </para></entry>
16445 </row>
16446 <row>
16447 <entry role="func_table_entry">
16448 <para role="func_signature">
16449 <function>json_serialize</function> (
16450 <replaceable>expression</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional>
16451 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional> )
16452 </para>
16453 <para>
16454 Converts an SQL/JSON expression into a character or binary string. The
16455 <replaceable>expression</replaceable> can be of any JSON type, any
16456 character string type, or <type>bytea</type> in UTF8 encoding.
16457 The returned type used in <literal> RETURNING</literal> can be any
16458 character string type or <type>bytea</type>. The default is
16459 <type>text</type>.
16460 </para>
16461 <para>
16462 <literal>json_serialize('{ "a" : 1 } ' RETURNING bytea)</literal>
16463 <returnvalue>\x7b20226122203a2031207d20</returnvalue>
16464 </para></entry>
16465 </row>
16466 </tbody>
16467 </tgroup>
16468 </table>
16470 <para>
16471 <xref linkend="functions-sqljson-misc" /> details SQL/JSON
16472 facilities for testing JSON.
16473 </para>
16475 <table id="functions-sqljson-misc">
16476 <title>SQL/JSON Testing Functions</title>
16477 <tgroup cols="1">
16478 <thead>
16479 <row>
16480 <entry role="func_table_entry"><para role="func_signature">
16481 Function signature
16482 </para>
16483 <para>
16484 Description
16485 </para>
16486 <para>
16487 Example(s)
16488 </para></entry>
16489 </row>
16490 </thead>
16491 <tbody>
16492 <row>
16493 <entry role="func_table_entry"><para role="func_signature">
16494 <indexterm><primary>IS JSON</primary></indexterm>
16495 <replaceable>expression</replaceable> <literal>IS</literal> <optional> <literal>NOT</literal> </optional> <literal>JSON</literal>
16496 <optional> { <literal>VALUE</literal> | <literal>SCALAR</literal> | <literal>ARRAY</literal> | <literal>OBJECT</literal> } </optional>
16497 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
16498 </para>
16499 <para>
16500 This predicate tests whether <replaceable>expression</replaceable> can be
16501 parsed as JSON, possibly of a specified type.
16502 If <literal>SCALAR</literal> or <literal>ARRAY</literal> or
16503 <literal>OBJECT</literal> is specified, the
16504 test is whether or not the JSON is of that particular type. If
16505 <literal>WITH UNIQUE KEYS</literal> is specified, then any object in the
16506 <replaceable>expression</replaceable> is also tested to see if it
16507 has duplicate keys.
16508 </para>
16509 <para>
16510 <programlisting>
16511 SELECT js,
16512 js IS JSON "json?",
16513 js IS JSON SCALAR "scalar?",
16514 js IS JSON OBJECT "object?",
16515 js IS JSON ARRAY "array?"
16516 FROM (VALUES
16517 ('123'), ('"abc"'), ('{"a": "b"}'), ('[1,2]'),('abc')) foo(js);
16518 js | json? | scalar? | object? | array?
16519 ------------+-------+---------+---------+--------
16520 123 | t | t | f | f
16521 "abc" | t | t | f | f
16522 {"a": "b"} | t | f | t | f
16523 [1,2] | t | f | f | t
16524 abc | f | f | f | f
16525 </programlisting>
16526 </para>
16527 <para>
16528 <programlisting>
16529 SELECT js,
16530 js IS JSON OBJECT "object?",
16531 js IS JSON ARRAY "array?",
16532 js IS JSON ARRAY WITH UNIQUE KEYS "array w. UK?",
16533 js IS JSON ARRAY WITHOUT UNIQUE KEYS "array w/o UK?"
16534 FROM (VALUES ('[{"a":"1"},
16535 {"b":"2","b":"3"}]')) foo(js);
16536 -[ RECORD 1 ]-+--------------------
16537 js | [{"a":"1"}, +
16538 | {"b":"2","b":"3"}]
16539 object? | f
16540 array? | t
16541 array w. UK? | f
16542 array w/o UK? | t
16543 </programlisting>
16544 </para></entry>
16545 </row>
16546 </tbody>
16547 </tgroup>
16548 </table>
16550 <para>
16551 <xref linkend="functions-json-processing-table"/> shows the functions that
16552 are available for processing <type>json</type> and <type>jsonb</type> values.
16553 </para>
16555 <table id="functions-json-processing-table">
16556 <title>JSON Processing Functions</title>
16557 <tgroup cols="1">
16558 <thead>
16559 <row>
16560 <entry role="func_table_entry"><para role="func_signature">
16561 Function
16562 </para>
16563 <para>
16564 Description
16565 </para>
16566 <para>
16567 Example(s)
16568 </para></entry>
16569 </row>
16570 </thead>
16572 <tbody>
16573 <row>
16574 <entry role="func_table_entry"><para role="func_signature">
16575 <indexterm>
16576 <primary>json_array_elements</primary>
16577 </indexterm>
16578 <function>json_array_elements</function> ( <type>json</type> )
16579 <returnvalue>setof json</returnvalue>
16580 </para>
16581 <para role="func_signature">
16582 <indexterm>
16583 <primary>jsonb_array_elements</primary>
16584 </indexterm>
16585 <function>jsonb_array_elements</function> ( <type>jsonb</type> )
16586 <returnvalue>setof jsonb</returnvalue>
16587 </para>
16588 <para>
16589 Expands the top-level JSON array into a set of JSON values.
16590 </para>
16591 <para>
16592 <literal>select * from json_array_elements('[1,true, [2,false]]')</literal>
16593 <returnvalue></returnvalue>
16594 <programlisting>
16595 value
16596 -----------
16598 true
16599 [2,false]
16600 </programlisting>
16601 </para></entry>
16602 </row>
16604 <row>
16605 <entry role="func_table_entry"><para role="func_signature">
16606 <indexterm>
16607 <primary>json_array_elements_text</primary>
16608 </indexterm>
16609 <function>json_array_elements_text</function> ( <type>json</type> )
16610 <returnvalue>setof text</returnvalue>
16611 </para>
16612 <para role="func_signature">
16613 <indexterm>
16614 <primary>jsonb_array_elements_text</primary>
16615 </indexterm>
16616 <function>jsonb_array_elements_text</function> ( <type>jsonb</type> )
16617 <returnvalue>setof text</returnvalue>
16618 </para>
16619 <para>
16620 Expands the top-level JSON array into a set of <type>text</type> values.
16621 </para>
16622 <para>
16623 <literal>select * from json_array_elements_text('["foo", "bar"]')</literal>
16624 <returnvalue></returnvalue>
16625 <programlisting>
16626 value
16627 -----------
16630 </programlisting>
16631 </para></entry>
16632 </row>
16634 <row>
16635 <entry role="func_table_entry"><para role="func_signature">
16636 <indexterm>
16637 <primary>json_array_length</primary>
16638 </indexterm>
16639 <function>json_array_length</function> ( <type>json</type> )
16640 <returnvalue>integer</returnvalue>
16641 </para>
16642 <para role="func_signature">
16643 <indexterm>
16644 <primary>jsonb_array_length</primary>
16645 </indexterm>
16646 <function>jsonb_array_length</function> ( <type>jsonb</type> )
16647 <returnvalue>integer</returnvalue>
16648 </para>
16649 <para>
16650 Returns the number of elements in the top-level JSON array.
16651 </para>
16652 <para>
16653 <literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal>
16654 <returnvalue>5</returnvalue>
16655 </para>
16656 <para>
16657 <literal>jsonb_array_length('[]')</literal>
16658 <returnvalue>0</returnvalue>
16659 </para></entry>
16660 </row>
16662 <row>
16663 <entry role="func_table_entry"><para role="func_signature">
16664 <indexterm>
16665 <primary>json_each</primary>
16666 </indexterm>
16667 <function>json_each</function> ( <type>json</type> )
16668 <returnvalue>setof record</returnvalue>
16669 ( <parameter>key</parameter> <type>text</type>,
16670 <parameter>value</parameter> <type>json</type> )
16671 </para>
16672 <para role="func_signature">
16673 <indexterm>
16674 <primary>jsonb_each</primary>
16675 </indexterm>
16676 <function>jsonb_each</function> ( <type>jsonb</type> )
16677 <returnvalue>setof record</returnvalue>
16678 ( <parameter>key</parameter> <type>text</type>,
16679 <parameter>value</parameter> <type>jsonb</type> )
16680 </para>
16681 <para>
16682 Expands the top-level JSON object into a set of key/value pairs.
16683 </para>
16684 <para>
16685 <literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal>
16686 <returnvalue></returnvalue>
16687 <programlisting>
16688 key | value
16689 -----+-------
16690 a | "foo"
16691 b | "bar"
16692 </programlisting>
16693 </para></entry>
16694 </row>
16696 <row>
16697 <entry role="func_table_entry"><para role="func_signature">
16698 <indexterm>
16699 <primary>json_each_text</primary>
16700 </indexterm>
16701 <function>json_each_text</function> ( <type>json</type> )
16702 <returnvalue>setof record</returnvalue>
16703 ( <parameter>key</parameter> <type>text</type>,
16704 <parameter>value</parameter> <type>text</type> )
16705 </para>
16706 <para role="func_signature">
16707 <indexterm>
16708 <primary>jsonb_each_text</primary>
16709 </indexterm>
16710 <function>jsonb_each_text</function> ( <type>jsonb</type> )
16711 <returnvalue>setof record</returnvalue>
16712 ( <parameter>key</parameter> <type>text</type>,
16713 <parameter>value</parameter> <type>text</type> )
16714 </para>
16715 <para>
16716 Expands the top-level JSON object into a set of key/value pairs.
16717 The returned <parameter>value</parameter>s will be of
16718 type <type>text</type>.
16719 </para>
16720 <para>
16721 <literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal>
16722 <returnvalue></returnvalue>
16723 <programlisting>
16724 key | value
16725 -----+-------
16726 a | foo
16727 b | bar
16728 </programlisting>
16729 </para></entry>
16730 </row>
16732 <row>
16733 <entry role="func_table_entry"><para role="func_signature">
16734 <indexterm>
16735 <primary>json_extract_path</primary>
16736 </indexterm>
16737 <function>json_extract_path</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16738 <returnvalue>json</returnvalue>
16739 </para>
16740 <para role="func_signature">
16741 <indexterm>
16742 <primary>jsonb_extract_path</primary>
16743 </indexterm>
16744 <function>jsonb_extract_path</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16745 <returnvalue>jsonb</returnvalue>
16746 </para>
16747 <para>
16748 Extracts JSON sub-object at the specified path.
16749 (This is functionally equivalent to the <literal>#&gt;</literal>
16750 operator, but writing the path out as a variadic list can be more
16751 convenient in some cases.)
16752 </para>
16753 <para>
16754 <literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
16755 <returnvalue>"foo"</returnvalue>
16756 </para></entry>
16757 </row>
16759 <row>
16760 <entry role="func_table_entry"><para role="func_signature">
16761 <indexterm>
16762 <primary>json_extract_path_text</primary>
16763 </indexterm>
16764 <function>json_extract_path_text</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16765 <returnvalue>text</returnvalue>
16766 </para>
16767 <para role="func_signature">
16768 <indexterm>
16769 <primary>jsonb_extract_path_text</primary>
16770 </indexterm>
16771 <function>jsonb_extract_path_text</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
16772 <returnvalue>text</returnvalue>
16773 </para>
16774 <para>
16775 Extracts JSON sub-object at the specified path as <type>text</type>.
16776 (This is functionally equivalent to the <literal>#&gt;&gt;</literal>
16777 operator.)
16778 </para>
16779 <para>
16780 <literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
16781 <returnvalue>foo</returnvalue>
16782 </para></entry>
16783 </row>
16785 <row>
16786 <entry role="func_table_entry"><para role="func_signature">
16787 <indexterm>
16788 <primary>json_object_keys</primary>
16789 </indexterm>
16790 <function>json_object_keys</function> ( <type>json</type> )
16791 <returnvalue>setof text</returnvalue>
16792 </para>
16793 <para role="func_signature">
16794 <indexterm>
16795 <primary>jsonb_object_keys</primary>
16796 </indexterm>
16797 <function>jsonb_object_keys</function> ( <type>jsonb</type> )
16798 <returnvalue>setof text</returnvalue>
16799 </para>
16800 <para>
16801 Returns the set of keys in the top-level JSON object.
16802 </para>
16803 <para>
16804 <literal>select * from json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal>
16805 <returnvalue></returnvalue>
16806 <programlisting>
16807 json_object_keys
16808 ------------------
16811 </programlisting>
16812 </para></entry>
16813 </row>
16815 <row>
16816 <entry role="func_table_entry"><para role="func_signature">
16817 <indexterm>
16818 <primary>json_populate_record</primary>
16819 </indexterm>
16820 <function>json_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16821 <returnvalue>anyelement</returnvalue>
16822 </para>
16823 <para role="func_signature">
16824 <indexterm>
16825 <primary>jsonb_populate_record</primary>
16826 </indexterm>
16827 <function>jsonb_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16828 <returnvalue>anyelement</returnvalue>
16829 </para>
16830 <para>
16831 Expands the top-level JSON object to a row having the composite type
16832 of the <parameter>base</parameter> argument. The JSON object
16833 is scanned for fields whose names match column names of the output row
16834 type, and their values are inserted into those columns of the output.
16835 (Fields that do not correspond to any output column name are ignored.)
16836 In typical use, the value of <parameter>base</parameter> is just
16837 <literal>NULL</literal>, which means that any output columns that do
16838 not match any object field will be filled with nulls. However,
16839 if <parameter>base</parameter> isn't <literal>NULL</literal> then
16840 the values it contains will be used for unmatched columns.
16841 </para>
16842 <para>
16843 To convert a JSON value to the SQL type of an output column, the
16844 following rules are applied in sequence:
16845 <itemizedlist spacing="compact">
16846 <listitem>
16847 <para>
16848 A JSON null value is converted to an SQL null in all cases.
16849 </para>
16850 </listitem>
16851 <listitem>
16852 <para>
16853 If the output column is of type <type>json</type>
16854 or <type>jsonb</type>, the JSON value is just reproduced exactly.
16855 </para>
16856 </listitem>
16857 <listitem>
16858 <para>
16859 If the output column is a composite (row) type, and the JSON value
16860 is a JSON object, the fields of the object are converted to columns
16861 of the output row type by recursive application of these rules.
16862 </para>
16863 </listitem>
16864 <listitem>
16865 <para>
16866 Likewise, if the output column is an array type and the JSON value
16867 is a JSON array, the elements of the JSON array are converted to
16868 elements of the output array by recursive application of these
16869 rules.
16870 </para>
16871 </listitem>
16872 <listitem>
16873 <para>
16874 Otherwise, if the JSON value is a string, the contents of the
16875 string are fed to the input conversion function for the column's
16876 data type.
16877 </para>
16878 </listitem>
16879 <listitem>
16880 <para>
16881 Otherwise, the ordinary text representation of the JSON value is
16882 fed to the input conversion function for the column's data type.
16883 </para>
16884 </listitem>
16885 </itemizedlist>
16886 </para>
16887 <para>
16888 While the example below uses a constant JSON value, typical use would
16889 be to reference a <type>json</type> or <type>jsonb</type> column
16890 laterally from another table in the query's <literal>FROM</literal>
16891 clause. Writing <function>json_populate_record</function> in
16892 the <literal>FROM</literal> clause is good practice, since all of the
16893 extracted columns are available for use without duplicate function
16894 calls.
16895 </para>
16896 <para>
16897 <literal>create type subrowtype as (d int, e text);</literal>
16898 <literal>create type myrowtype as (a int, b text[], c subrowtype);</literal>
16899 </para>
16900 <para>
16901 <literal>select * from json_populate_record(null::myrowtype,
16902 '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}, "x": "foo"}')</literal>
16903 <returnvalue></returnvalue>
16904 <programlisting>
16905 a | b | c
16906 ---+-----------+-------------
16907 1 | {2,"a b"} | (4,"a b c")
16908 </programlisting>
16909 </para></entry>
16910 </row>
16912 <row>
16913 <entry role="func_table_entry"><para role="func_signature">
16914 <indexterm>
16915 <primary>jsonb_populate_record_valid</primary>
16916 </indexterm>
16917 <function>jsonb_populate_record_valid</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16918 <returnvalue>boolean</returnvalue>
16919 </para>
16920 <para>
16921 Function for testing <function>jsonb_populate_record</function>. Returns
16922 <literal>true</literal> if the input <function>jsonb_populate_record</function>
16923 would finish without an error for the given input JSON object; that is, it's
16924 valid input, <literal>false</literal> otherwise.
16925 </para>
16926 <para>
16927 <literal>create type jsb_char2 as (a char(2));</literal>
16928 </para>
16929 <para>
16930 <literal>select jsonb_populate_record_valid(NULL::jsb_char2, '{"a": "aaa"}');</literal>
16931 <returnvalue></returnvalue>
16932 <programlisting>
16933 jsonb_populate_record_valid
16934 -----------------------------
16936 (1 row)
16937 </programlisting>
16939 <literal>select * from jsonb_populate_record(NULL::jsb_char2, '{"a": "aaa"}') q;</literal>
16940 <returnvalue></returnvalue>
16941 <programlisting>
16942 ERROR: value too long for type character(2)
16943 </programlisting>
16944 <literal>select jsonb_populate_record_valid(NULL::jsb_char2, '{"a": "aa"}');</literal>
16945 <returnvalue></returnvalue>
16946 <programlisting>
16947 jsonb_populate_record_valid
16948 -----------------------------
16950 (1 row)
16951 </programlisting>
16953 <literal>select * from jsonb_populate_record(NULL::jsb_char2, '{"a": "aa"}') q;</literal>
16954 <returnvalue></returnvalue>
16955 <programlisting>
16957 ----
16959 (1 row)
16960 </programlisting>
16961 </para></entry>
16962 </row>
16964 <row>
16965 <entry role="func_table_entry"><para role="func_signature">
16966 <indexterm>
16967 <primary>json_populate_recordset</primary>
16968 </indexterm>
16969 <function>json_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16970 <returnvalue>setof anyelement</returnvalue>
16971 </para>
16972 <para role="func_signature">
16973 <indexterm>
16974 <primary>jsonb_populate_recordset</primary>
16975 </indexterm>
16976 <function>jsonb_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16977 <returnvalue>setof anyelement</returnvalue>
16978 </para>
16979 <para>
16980 Expands the top-level JSON array of objects to a set of rows having
16981 the composite type of the <parameter>base</parameter> argument.
16982 Each element of the JSON array is processed as described above
16983 for <function>json[b]_populate_record</function>.
16984 </para>
16985 <para>
16986 <literal>create type twoints as (a int, b int);</literal>
16987 </para>
16988 <para>
16989 <literal>select * from json_populate_recordset(null::twoints, '[{"a":1,"b":2}, {"a":3,"b":4}]')</literal>
16990 <returnvalue></returnvalue>
16991 <programlisting>
16992 a | b
16993 ---+---
16994 1 | 2
16995 3 | 4
16996 </programlisting>
16997 </para></entry>
16998 </row>
17000 <row>
17001 <entry role="func_table_entry"><para role="func_signature">
17002 <indexterm>
17003 <primary>json_to_record</primary>
17004 </indexterm>
17005 <function>json_to_record</function> ( <type>json</type> )
17006 <returnvalue>record</returnvalue>
17007 </para>
17008 <para role="func_signature">
17009 <indexterm>
17010 <primary>jsonb_to_record</primary>
17011 </indexterm>
17012 <function>jsonb_to_record</function> ( <type>jsonb</type> )
17013 <returnvalue>record</returnvalue>
17014 </para>
17015 <para>
17016 Expands the top-level JSON object to a row having the composite type
17017 defined by an <literal>AS</literal> clause. (As with all functions
17018 returning <type>record</type>, the calling query must explicitly
17019 define the structure of the record with an <literal>AS</literal>
17020 clause.) The output record is filled from fields of the JSON object,
17021 in the same way as described above
17022 for <function>json[b]_populate_record</function>. Since there is no
17023 input record value, unmatched columns are always filled with nulls.
17024 </para>
17025 <para>
17026 <literal>create type myrowtype as (a int, b text);</literal>
17027 </para>
17028 <para>
17029 <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>
17030 <returnvalue></returnvalue>
17031 <programlisting>
17032 a | b | c | d | r
17033 ---+---------+---------+---+---------------
17034 1 | [1,2,3] | {1,2,3} | | (123,"a b c")
17035 </programlisting>
17036 </para></entry>
17037 </row>
17039 <row>
17040 <entry role="func_table_entry"><para role="func_signature">
17041 <indexterm>
17042 <primary>json_to_recordset</primary>
17043 </indexterm>
17044 <function>json_to_recordset</function> ( <type>json</type> )
17045 <returnvalue>setof record</returnvalue>
17046 </para>
17047 <para role="func_signature">
17048 <indexterm>
17049 <primary>jsonb_to_recordset</primary>
17050 </indexterm>
17051 <function>jsonb_to_recordset</function> ( <type>jsonb</type> )
17052 <returnvalue>setof record</returnvalue>
17053 </para>
17054 <para>
17055 Expands the top-level JSON array of objects to a set of rows having
17056 the composite type defined by an <literal>AS</literal> clause. (As
17057 with all functions returning <type>record</type>, the calling query
17058 must explicitly define the structure of the record with
17059 an <literal>AS</literal> clause.) Each element of the JSON array is
17060 processed as described above
17061 for <function>json[b]_populate_record</function>.
17062 </para>
17063 <para>
17064 <literal>select * from json_to_recordset('[{"a":1,"b":"foo"}, {"a":"2","c":"bar"}]') as x(a int, b text)</literal>
17065 <returnvalue></returnvalue>
17066 <programlisting>
17067 a | b
17068 ---+-----
17069 1 | foo
17071 </programlisting>
17072 </para></entry>
17073 </row>
17075 <row>
17076 <entry role="func_table_entry"><para role="func_signature">
17077 <indexterm>
17078 <primary>jsonb_set</primary>
17079 </indexterm>
17080 <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> )
17081 <returnvalue>jsonb</returnvalue>
17082 </para>
17083 <para>
17084 Returns <parameter>target</parameter>
17085 with the item designated by <parameter>path</parameter>
17086 replaced by <parameter>new_value</parameter>, or with
17087 <parameter>new_value</parameter> added if
17088 <parameter>create_if_missing</parameter> is true (which is the
17089 default) and the item designated by <parameter>path</parameter>
17090 does not exist.
17091 All earlier steps in the path must exist, or
17092 the <parameter>target</parameter> is returned unchanged.
17093 As with the path oriented operators, negative integers that
17094 appear in the <parameter>path</parameter> count from the end
17095 of JSON arrays.
17096 If the last path step is an array index that is out of range,
17097 and <parameter>create_if_missing</parameter> is true, the new
17098 value is added at the beginning of the array if the index is negative,
17099 or at the end of the array if it is positive.
17100 </para>
17101 <para>
17102 <literal>jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', '[2,3,4]', false)</literal>
17103 <returnvalue>[{"f1": [2, 3, 4], "f2": null}, 2, null, 3]</returnvalue>
17104 </para>
17105 <para>
17106 <literal>jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}', '[2,3,4]')</literal>
17107 <returnvalue>[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</returnvalue>
17108 </para></entry>
17109 </row>
17111 <row>
17112 <entry role="func_table_entry"><para role="func_signature">
17113 <indexterm>
17114 <primary>jsonb_set_lax</primary>
17115 </indexterm>
17116 <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> )
17117 <returnvalue>jsonb</returnvalue>
17118 </para>
17119 <para>
17120 If <parameter>new_value</parameter> is not <literal>NULL</literal>,
17121 behaves identically to <literal>jsonb_set</literal>. Otherwise behaves
17122 according to the value
17123 of <parameter>null_value_treatment</parameter> which must be one
17124 of <literal>'raise_exception'</literal>,
17125 <literal>'use_json_null'</literal>, <literal>'delete_key'</literal>, or
17126 <literal>'return_target'</literal>. The default is
17127 <literal>'use_json_null'</literal>.
17128 </para>
17129 <para>
17130 <literal>jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null)</literal>
17131 <returnvalue>[{"f1": null, "f2": null}, 2, null, 3]</returnvalue>
17132 </para>
17133 <para>
17134 <literal>jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true, 'return_target')</literal>
17135 <returnvalue>[{"f1": 99, "f2": null}, 2]</returnvalue>
17136 </para></entry>
17137 </row>
17139 <row>
17140 <entry role="func_table_entry"><para role="func_signature">
17141 <indexterm>
17142 <primary>jsonb_insert</primary>
17143 </indexterm>
17144 <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> )
17145 <returnvalue>jsonb</returnvalue>
17146 </para>
17147 <para>
17148 Returns <parameter>target</parameter>
17149 with <parameter>new_value</parameter> inserted. If the item
17150 designated by the <parameter>path</parameter> is an array
17151 element, <parameter>new_value</parameter> will be inserted before
17152 that item if <parameter>insert_after</parameter> is false (which
17153 is the default), or after it
17154 if <parameter>insert_after</parameter> is true. If the item
17155 designated by the <parameter>path</parameter> is an object
17156 field, <parameter>new_value</parameter> will be inserted only if
17157 the object does not already contain that key.
17158 All earlier steps in the path must exist, or
17159 the <parameter>target</parameter> is returned unchanged.
17160 As with the path oriented operators, negative integers that
17161 appear in the <parameter>path</parameter> count from the end
17162 of JSON arrays.
17163 If the last path step is an array index that is out of range, the new
17164 value is added at the beginning of the array if the index is negative,
17165 or at the end of the array if it is positive.
17166 </para>
17167 <para>
17168 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')</literal>
17169 <returnvalue>{"a": [0, "new_value", 1, 2]}</returnvalue>
17170 </para>
17171 <para>
17172 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)</literal>
17173 <returnvalue>{"a": [0, 1, "new_value", 2]}</returnvalue>
17174 </para></entry>
17175 </row>
17177 <row>
17178 <entry role="func_table_entry"><para role="func_signature">
17179 <indexterm>
17180 <primary>json_strip_nulls</primary>
17181 </indexterm>
17182 <function>json_strip_nulls</function> ( <type>json</type> )
17183 <returnvalue>json</returnvalue>
17184 </para>
17185 <para role="func_signature">
17186 <indexterm>
17187 <primary>jsonb_strip_nulls</primary>
17188 </indexterm>
17189 <function>jsonb_strip_nulls</function> ( <type>jsonb</type> )
17190 <returnvalue>jsonb</returnvalue>
17191 </para>
17192 <para>
17193 Deletes all object fields that have null values from the given JSON
17194 value, recursively. Null values that are not object fields are
17195 untouched.
17196 </para>
17197 <para>
17198 <literal>json_strip_nulls('[{"f1":1, "f2":null}, 2, null, 3]')</literal>
17199 <returnvalue>[{"f1":1},2,null,3]</returnvalue>
17200 </para></entry>
17201 </row>
17203 <row>
17204 <entry role="func_table_entry"><para role="func_signature">
17205 <indexterm>
17206 <primary>jsonb_path_exists</primary>
17207 </indexterm>
17208 <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> )
17209 <returnvalue>boolean</returnvalue>
17210 </para>
17211 <para>
17212 Checks whether the JSON path returns any item for the specified JSON
17213 value.
17214 (This is useful only with SQL-standard JSON path expressions, not
17215 <link linkend="functions-sqljson-check-expressions">predicate check
17216 expressions</link>, since those always return a value.)
17217 If the <parameter>vars</parameter> argument is specified, it must
17218 be a JSON object, and its fields provide named values to be
17219 substituted into the <type>jsonpath</type> expression.
17220 If the <parameter>silent</parameter> argument is specified and
17221 is <literal>true</literal>, the function suppresses the same errors
17222 as the <literal>@?</literal> and <literal>@@</literal> operators do.
17223 </para>
17224 <para>
17225 <literal>jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
17226 <returnvalue>t</returnvalue>
17227 </para></entry>
17228 </row>
17230 <row>
17231 <entry role="func_table_entry"><para role="func_signature">
17232 <indexterm>
17233 <primary>jsonb_path_match</primary>
17234 </indexterm>
17235 <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> )
17236 <returnvalue>boolean</returnvalue>
17237 </para>
17238 <para>
17239 Returns the SQL boolean result of a JSON path predicate check
17240 for the specified JSON value.
17241 (This is useful only
17242 with <link linkend="functions-sqljson-check-expressions">predicate
17243 check expressions</link>, not SQL-standard JSON path expressions,
17244 since it will either fail or return <literal>NULL</literal> if the
17245 path result is not a single boolean value.)
17246 The optional <parameter>vars</parameter>
17247 and <parameter>silent</parameter> arguments act the same as
17248 for <function>jsonb_path_exists</function>.
17249 </para>
17250 <para>
17251 <literal>jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max))', '{"min":2, "max":4}')</literal>
17252 <returnvalue>t</returnvalue>
17253 </para></entry>
17254 </row>
17256 <row>
17257 <entry role="func_table_entry"><para role="func_signature">
17258 <indexterm>
17259 <primary>jsonb_path_query</primary>
17260 </indexterm>
17261 <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> )
17262 <returnvalue>setof jsonb</returnvalue>
17263 </para>
17264 <para>
17265 Returns all JSON items returned by the JSON path for the specified
17266 JSON value.
17267 For SQL-standard JSON path expressions it returns the JSON
17268 values selected from <parameter>target</parameter>.
17269 For <link linkend="functions-sqljson-check-expressions">predicate
17270 check expressions</link> it returns the result of the predicate
17271 check: <literal>true</literal>, <literal>false</literal>,
17272 or <literal>null</literal>.
17273 The optional <parameter>vars</parameter>
17274 and <parameter>silent</parameter> arguments act the same as
17275 for <function>jsonb_path_exists</function>.
17276 </para>
17277 <para>
17278 <literal>select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
17279 <returnvalue></returnvalue>
17280 <programlisting>
17281 jsonb_path_query
17282 ------------------
17286 </programlisting>
17287 </para></entry>
17288 </row>
17290 <row>
17291 <entry role="func_table_entry"><para role="func_signature">
17292 <indexterm>
17293 <primary>jsonb_path_query_array</primary>
17294 </indexterm>
17295 <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> )
17296 <returnvalue>jsonb</returnvalue>
17297 </para>
17298 <para>
17299 Returns all JSON items returned by the JSON path for the specified
17300 JSON value, as a JSON array.
17301 The parameters are the same as
17302 for <function>jsonb_path_query</function>.
17303 </para>
17304 <para>
17305 <literal>jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
17306 <returnvalue>[2, 3, 4]</returnvalue>
17307 </para></entry>
17308 </row>
17310 <row>
17311 <entry role="func_table_entry"><para role="func_signature">
17312 <indexterm>
17313 <primary>jsonb_path_query_first</primary>
17314 </indexterm>
17315 <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> )
17316 <returnvalue>jsonb</returnvalue>
17317 </para>
17318 <para>
17319 Returns the first JSON item returned by the JSON path for the
17320 specified JSON value, or <literal>NULL</literal> if there are no
17321 results.
17322 The parameters are the same as
17323 for <function>jsonb_path_query</function>.
17324 </para>
17325 <para>
17326 <literal>jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
17327 <returnvalue>2</returnvalue>
17328 </para></entry>
17329 </row>
17331 <row>
17332 <entry role="func_table_entry"><para role="func_signature">
17333 <indexterm>
17334 <primary>jsonb_path_exists_tz</primary>
17335 </indexterm>
17336 <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> )
17337 <returnvalue>boolean</returnvalue>
17338 </para>
17339 <para role="func_signature">
17340 <indexterm>
17341 <primary>jsonb_path_match_tz</primary>
17342 </indexterm>
17343 <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> )
17344 <returnvalue>boolean</returnvalue>
17345 </para>
17346 <para role="func_signature">
17347 <indexterm>
17348 <primary>jsonb_path_query_tz</primary>
17349 </indexterm>
17350 <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> )
17351 <returnvalue>setof jsonb</returnvalue>
17352 </para>
17353 <para role="func_signature">
17354 <indexterm>
17355 <primary>jsonb_path_query_array_tz</primary>
17356 </indexterm>
17357 <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> )
17358 <returnvalue>jsonb</returnvalue>
17359 </para>
17360 <para role="func_signature">
17361 <indexterm>
17362 <primary>jsonb_path_query_first_tz</primary>
17363 </indexterm>
17364 <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> )
17365 <returnvalue>jsonb</returnvalue>
17366 </para>
17367 <para>
17368 These functions act like their counterparts described above without
17369 the <literal>_tz</literal> suffix, except that these functions support
17370 comparisons of date/time values that require timezone-aware
17371 conversions. The example below requires interpretation of the
17372 date-only value <literal>2015-08-02</literal> as a timestamp with time
17373 zone, so the result depends on the current
17374 <xref linkend="guc-timezone"/> setting. Due to this dependency, these
17375 functions are marked as stable, which means these functions cannot be
17376 used in indexes. Their counterparts are immutable, and so can be used
17377 in indexes; but they will throw errors if asked to make such
17378 comparisons.
17379 </para>
17380 <para>
17381 <literal>jsonb_path_exists_tz('["2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime() &lt; "2015-08-02".datetime())')</literal>
17382 <returnvalue>t</returnvalue>
17383 </para></entry>
17384 </row>
17386 <row>
17387 <entry role="func_table_entry"><para role="func_signature">
17388 <indexterm>
17389 <primary>jsonb_pretty</primary>
17390 </indexterm>
17391 <function>jsonb_pretty</function> ( <type>jsonb</type> )
17392 <returnvalue>text</returnvalue>
17393 </para>
17394 <para>
17395 Converts the given JSON value to pretty-printed, indented text.
17396 </para>
17397 <para>
17398 <literal>jsonb_pretty('[{"f1":1,"f2":null}, 2]')</literal>
17399 <returnvalue></returnvalue>
17400 <programlisting>
17403 "f1": 1,
17404 "f2": null
17408 </programlisting>
17409 </para></entry>
17410 </row>
17412 <row>
17413 <entry role="func_table_entry"><para role="func_signature">
17414 <indexterm>
17415 <primary>json_typeof</primary>
17416 </indexterm>
17417 <function>json_typeof</function> ( <type>json</type> )
17418 <returnvalue>text</returnvalue>
17419 </para>
17420 <para role="func_signature">
17421 <indexterm>
17422 <primary>jsonb_typeof</primary>
17423 </indexterm>
17424 <function>jsonb_typeof</function> ( <type>jsonb</type> )
17425 <returnvalue>text</returnvalue>
17426 </para>
17427 <para>
17428 Returns the type of the top-level JSON value as a text string.
17429 Possible types are
17430 <literal>object</literal>, <literal>array</literal>,
17431 <literal>string</literal>, <literal>number</literal>,
17432 <literal>boolean</literal>, and <literal>null</literal>.
17433 (The <literal>null</literal> result should not be confused
17434 with an SQL NULL; see the examples.)
17435 </para>
17436 <para>
17437 <literal>json_typeof('-123.4')</literal>
17438 <returnvalue>number</returnvalue>
17439 </para>
17440 <para>
17441 <literal>json_typeof('null'::json)</literal>
17442 <returnvalue>null</returnvalue>
17443 </para>
17444 <para>
17445 <literal>json_typeof(NULL::json) IS NULL</literal>
17446 <returnvalue>t</returnvalue>
17447 </para></entry>
17448 </row>
17449 </tbody>
17450 </tgroup>
17451 </table>
17452 </sect2>
17454 <sect2 id="functions-sqljson-path">
17455 <title>The SQL/JSON Path Language</title>
17457 <indexterm zone="functions-sqljson-path">
17458 <primary>SQL/JSON path language</primary>
17459 </indexterm>
17461 <para>
17462 SQL/JSON path expressions specify item(s) to be retrieved
17463 from a JSON value, similarly to XPath expressions used
17464 for access to XML content. In <productname>PostgreSQL</productname>,
17465 path expressions are implemented as the <type>jsonpath</type>
17466 data type and can use any elements described in
17467 <xref linkend="datatype-jsonpath"/>.
17468 </para>
17470 <para>
17471 JSON query functions and operators
17472 pass the provided path expression to the <firstterm>path engine</firstterm>
17473 for evaluation. If the expression matches the queried JSON data,
17474 the corresponding JSON item, or set of items, is returned.
17475 If there is no match, the result will be <literal>NULL</literal>,
17476 <literal>false</literal>, or an error, depending on the function.
17477 Path expressions are written in the SQL/JSON path language
17478 and can include arithmetic expressions and functions.
17479 </para>
17481 <para>
17482 A path expression consists of a sequence of elements allowed
17483 by the <type>jsonpath</type> data type.
17484 The path expression is normally evaluated from left to right, but
17485 you can use parentheses to change the order of operations.
17486 If the evaluation is successful, a sequence of JSON items is produced,
17487 and the evaluation result is returned to the JSON query function
17488 that completes the specified computation.
17489 </para>
17491 <para>
17492 To refer to the JSON value being queried (the
17493 <firstterm>context item</firstterm>), use the <literal>$</literal> variable
17494 in the path expression. The first element of a path must always
17495 be <literal>$</literal>. It can be followed by one or more
17496 <link linkend="type-jsonpath-accessors">accessor operators</link>,
17497 which go down the JSON structure level by level to retrieve sub-items
17498 of the context item. Each accessor operator acts on the
17499 result(s) of the previous evaluation step, producing zero, one, or more
17500 output items from each input item.
17501 </para>
17503 <para>
17504 For example, suppose you have some JSON data from a GPS tracker that you
17505 would like to parse, such as:
17506 <programlisting>
17507 SELECT '{
17508 "track": {
17509 "segments": [
17511 "location": [ 47.763, 13.4034 ],
17512 "start time": "2018-10-14 10:05:14",
17513 "HR": 73
17516 "location": [ 47.706, 13.2635 ],
17517 "start time": "2018-10-14 10:39:21",
17518 "HR": 135
17522 }' AS json \gset
17523 </programlisting>
17524 (The above example can be copied-and-pasted
17525 into <application>psql</application> to set things up for the following
17526 examples. Then <application>psql</application> will
17527 expand <literal>:'json'</literal> into a suitably-quoted string
17528 constant containing the JSON value.)
17529 </para>
17531 <para>
17532 To retrieve the available track segments, you need to use the
17533 <literal>.<replaceable>key</replaceable></literal> accessor
17534 operator to descend through surrounding JSON objects, for example:
17535 <screen>
17536 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments');</userinput>
17537 jsonb_path_query
17538 -----------------------------------------------------------&zwsp;-----------------------------------------------------------&zwsp;---------------------------------------------
17539 [{"HR": 73, "location": [47.763, 13.4034], "start time": "2018-10-14 10:05:14"}, {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"}]
17540 </screen>
17541 </para>
17543 <para>
17544 To retrieve the contents of an array, you typically use the
17545 <literal>[*]</literal> operator.
17546 The following example will return the location coordinates for all
17547 the available track segments:
17548 <screen>
17549 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].location');</userinput>
17550 jsonb_path_query
17551 -------------------
17552 [47.763, 13.4034]
17553 [47.706, 13.2635]
17554 </screen>
17555 Here we started with the whole JSON input value (<literal>$</literal>),
17556 then the <literal>.track</literal> accessor selected the JSON object
17557 associated with the <literal>"track"</literal> object key, then
17558 the <literal>.segments</literal> accessor selected the JSON array
17559 associated with the <literal>"segments"</literal> key within that
17560 object, then the <literal>[*]</literal> accessor selected each element
17561 of that array (producing a series of items), then
17562 the <literal>.location</literal> accessor selected the JSON array
17563 associated with the <literal>"location"</literal> key within each of
17564 those objects. In this example, each of those objects had
17565 a <literal>"location"</literal> key; but if any of them did not,
17566 the <literal>.location</literal> accessor would have simply produced no
17567 output for that input item.
17568 </para>
17570 <para>
17571 To return the coordinates of the first segment only, you can
17572 specify the corresponding subscript in the <literal>[]</literal>
17573 accessor operator. Recall that JSON array indexes are 0-relative:
17574 <screen>
17575 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[0].location');</userinput>
17576 jsonb_path_query
17577 -------------------
17578 [47.763, 13.4034]
17579 </screen>
17580 </para>
17582 <para>
17583 The result of each path evaluation step can be processed
17584 by one or more of the <type>jsonpath</type> operators and methods
17585 listed in <xref linkend="functions-sqljson-path-operators"/>.
17586 Each method name must be preceded by a dot. For example,
17587 you can get the size of an array:
17588 <screen>
17589 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments.size()');</userinput>
17590 jsonb_path_query
17591 ------------------
17593 </screen>
17594 More examples of using <type>jsonpath</type> operators
17595 and methods within path expressions appear below in
17596 <xref linkend="functions-sqljson-path-operators"/>.
17597 </para>
17599 <para>
17600 A path can also contain
17601 <firstterm>filter expressions</firstterm> that work similarly to the
17602 <literal>WHERE</literal> clause in SQL. A filter expression begins with
17603 a question mark and provides a condition in parentheses:
17605 <synopsis>
17606 ? (<replaceable>condition</replaceable>)
17607 </synopsis>
17608 </para>
17610 <para>
17611 Filter expressions must be written just after the path evaluation step
17612 to which they should apply. The result of that step is filtered to include
17613 only those items that satisfy the provided condition. SQL/JSON defines
17614 three-valued logic, so the condition can
17615 produce <literal>true</literal>, <literal>false</literal>,
17616 or <literal>unknown</literal>. The <literal>unknown</literal> value
17617 plays the same role as SQL <literal>NULL</literal> and can be tested
17618 for with the <literal>is unknown</literal> predicate. Further path
17619 evaluation steps use only those items for which the filter expression
17620 returned <literal>true</literal>.
17621 </para>
17623 <para>
17624 The functions and operators that can be used in filter expressions are
17625 listed in <xref linkend="functions-sqljson-filter-ex-table"/>. Within a
17626 filter expression, the <literal>@</literal> variable denotes the value
17627 being considered (i.e., one result of the preceding path step). You can
17628 write accessor operators after <literal>@</literal> to retrieve component
17629 items.
17630 </para>
17632 <para>
17633 For example, suppose you would like to retrieve all heart rate values higher
17634 than 130. You can achieve this as follows:
17635 <screen>
17636 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].HR ? (@ &gt; 130)');</userinput>
17637 jsonb_path_query
17638 ------------------
17640 </screen>
17641 </para>
17643 <para>
17644 To get the start times of segments with such values, you have to
17645 filter out irrelevant segments before selecting the start times, so the
17646 filter expression is applied to the previous step, and the path used
17647 in the condition is different:
17648 <screen>
17649 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.HR &gt; 130)."start time"');</userinput>
17650 jsonb_path_query
17651 -----------------------
17652 "2018-10-14 10:39:21"
17653 </screen>
17654 </para>
17656 <para>
17657 You can use several filter expressions in sequence, if required.
17658 The following example selects start times of all segments that
17659 contain locations with relevant coordinates and high heart rate values:
17660 <screen>
17661 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] &lt; 13.4) ? (@.HR &gt; 130)."start time"');</userinput>
17662 jsonb_path_query
17663 -----------------------
17664 "2018-10-14 10:39:21"
17665 </screen>
17666 </para>
17668 <para>
17669 Using filter expressions at different nesting levels is also allowed.
17670 The following example first filters all segments by location, and then
17671 returns high heart rate values for these segments, if available:
17672 <screen>
17673 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[1] &lt; 13.4).HR ? (@ &gt; 130)');</userinput>
17674 jsonb_path_query
17675 ------------------
17677 </screen>
17678 </para>
17680 <para>
17681 You can also nest filter expressions within each other.
17682 This example returns the size of the track if it contains any
17683 segments with high heart rate values, or an empty sequence otherwise:
17684 <screen>
17685 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track ? (exists(@.segments[*] ? (@.HR &gt; 130))).segments.size()');</userinput>
17686 jsonb_path_query
17687 ------------------
17689 </screen>
17690 </para>
17692 <sect3 id="functions-sqljson-deviations">
17693 <title>Deviations from the SQL Standard</title>
17694 <para>
17695 <productname>PostgreSQL</productname>'s implementation of the SQL/JSON path
17696 language has the following deviations from the SQL/JSON standard.
17697 </para>
17699 <sect4 id="functions-sqljson-check-expressions">
17700 <title>Boolean Predicate Check Expressions</title>
17701 <para>
17702 As an extension to the SQL standard,
17703 a <productname>PostgreSQL</productname> path expression can be a
17704 Boolean predicate, whereas the SQL standard allows predicates only within
17705 filters. While SQL-standard path expressions return the relevant
17706 element(s) of the queried JSON value, predicate check expressions
17707 return the single three-valued <type>jsonb</type> result of the
17708 predicate: <literal>true</literal>,
17709 <literal>false</literal>, or <literal>null</literal>.
17710 For example, we could write this SQL-standard filter expression:
17711 <screen>
17712 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments ?(@[*].HR &gt; 130)');</userinput>
17713 jsonb_path_query
17714 -----------------------------------------------------------&zwsp;----------------------
17715 {"HR": 135, "location": [47.706, 13.2635], "start time": "2018-10-14 10:39:21"}
17716 </screen>
17717 The similar predicate check expression simply
17718 returns <literal>true</literal>, indicating that a match exists:
17719 <screen>
17720 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].HR &gt; 130');</userinput>
17721 jsonb_path_query
17722 ------------------
17723 true
17724 </screen>
17725 </para>
17727 <note>
17728 <para>
17729 Predicate check expressions are required in the
17730 <literal>@@</literal> operator (and the
17731 <function>jsonb_path_match</function> function), and should not be used
17732 with the <literal>@?</literal> operator (or the
17733 <function>jsonb_path_exists</function> function).
17734 </para>
17735 </note>
17736 </sect4>
17738 <sect4 id="functions-sqljson-regular-expression-deviation">
17739 <title>Regular Expression Interpretation</title>
17740 <para>
17741 There are minor differences in the interpretation of regular
17742 expression patterns used in <literal>like_regex</literal> filters, as
17743 described in <xref linkend="jsonpath-regular-expressions"/>.
17744 </para>
17745 </sect4>
17746 </sect3>
17748 <sect3 id="functions-sqljson-strict-and-lax-modes">
17749 <title>Strict and Lax Modes</title>
17750 <para>
17751 When you query JSON data, the path expression may not match the
17752 actual JSON data structure. An attempt to access a non-existent
17753 member of an object or element of an array is defined as a
17754 structural error. SQL/JSON path expressions have two modes
17755 of handling structural errors:
17756 </para>
17758 <itemizedlist>
17759 <listitem>
17760 <para>
17761 lax (default) &mdash; the path engine implicitly adapts
17762 the queried data to the specified path.
17763 Any structural errors that cannot be fixed as described below
17764 are suppressed, producing no match.
17765 </para>
17766 </listitem>
17767 <listitem>
17768 <para>
17769 strict &mdash; if a structural error occurs, an error is raised.
17770 </para>
17771 </listitem>
17772 </itemizedlist>
17774 <para>
17775 Lax mode facilitates matching of a JSON document and path
17776 expression when the JSON data does not conform to the expected schema.
17777 If an operand does not match the requirements of a particular operation,
17778 it can be automatically wrapped as an SQL/JSON array, or unwrapped by
17779 converting its elements into an SQL/JSON sequence before performing
17780 the operation. Also, comparison operators automatically unwrap their
17781 operands in lax mode, so you can compare SQL/JSON arrays
17782 out-of-the-box. An array of size 1 is considered equal to its sole element.
17783 Automatic unwrapping is not performed when:
17784 <itemizedlist>
17785 <listitem>
17786 <para>
17787 The path expression contains <literal>type()</literal> or
17788 <literal>size()</literal> methods that return the type
17789 and the number of elements in the array, respectively.
17790 </para>
17791 </listitem>
17792 <listitem>
17793 <para>
17794 The queried JSON data contain nested arrays. In this case, only
17795 the outermost array is unwrapped, while all the inner arrays
17796 remain unchanged. Thus, implicit unwrapping can only go one
17797 level down within each path evaluation step.
17798 </para>
17799 </listitem>
17800 </itemizedlist>
17801 </para>
17803 <para>
17804 For example, when querying the GPS data listed above, you can
17805 abstract from the fact that it stores an array of segments
17806 when using lax mode:
17807 <screen>
17808 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments.location');</userinput>
17809 jsonb_path_query
17810 -------------------
17811 [47.763, 13.4034]
17812 [47.706, 13.2635]
17813 </screen>
17814 </para>
17816 <para>
17817 In strict mode, the specified path must exactly match the structure of
17818 the queried JSON document, so using this path
17819 expression will cause an error:
17820 <screen>
17821 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments.location');</userinput>
17822 ERROR: jsonpath member accessor can only be applied to an object
17823 </screen>
17824 To get the same result as in lax mode, you have to explicitly unwrap the
17825 <literal>segments</literal> array:
17826 <screen>
17827 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments[*].location');</userinput>
17828 jsonb_path_query
17829 -------------------
17830 [47.763, 13.4034]
17831 [47.706, 13.2635]
17832 </screen>
17833 </para>
17835 <para>
17836 The unwrapping behavior of lax mode can lead to surprising results. For
17837 instance, the following query using the <literal>.**</literal> accessor
17838 selects every <literal>HR</literal> value twice:
17839 <screen>
17840 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'lax $.**.HR');</userinput>
17841 jsonb_path_query
17842 ------------------
17847 </screen>
17848 This happens because the <literal>.**</literal> accessor selects both
17849 the <literal>segments</literal> array and each of its elements, while
17850 the <literal>.HR</literal> accessor automatically unwraps arrays when
17851 using lax mode. To avoid surprising results, we recommend using
17852 the <literal>.**</literal> accessor only in strict mode. The
17853 following query selects each <literal>HR</literal> value just once:
17854 <screen>
17855 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'strict $.**.HR');</userinput>
17856 jsonb_path_query
17857 ------------------
17860 </screen>
17861 </para>
17863 <para>
17864 The unwrapping of arrays can also lead to unexpected results. Consider this
17865 example, which selects all the <literal>location</literal> arrays:
17866 <screen>
17867 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments[*].location');</userinput>
17868 jsonb_path_query
17869 -------------------
17870 [47.763, 13.4034]
17871 [47.706, 13.2635]
17872 (2 rows)
17873 </screen>
17874 As expected it returns the full arrays. But applying a filter expression
17875 causes the arrays to be unwrapped to evaluate each item, returning only the
17876 items that match the expression:
17877 <screen>
17878 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments[*].location ?(@[*] &gt; 15)');</userinput>
17879 jsonb_path_query
17880 ------------------
17881 47.763
17882 47.706
17883 (2 rows)
17884 </screen>
17885 This despite the fact that the full arrays are selected by the path
17886 expression. Use strict mode to restore selecting the arrays:
17887 <screen>
17888 <prompt>=&gt;</prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments[*].location ?(@[*] &gt; 15)');</userinput>
17889 jsonb_path_query
17890 -------------------
17891 [47.763, 13.4034]
17892 [47.706, 13.2635]
17893 (2 rows)
17894 </screen>
17895 </para>
17896 </sect3>
17898 <sect3 id="functions-sqljson-path-operators">
17899 <title>SQL/JSON Path Operators and Methods</title>
17901 <para>
17902 <xref linkend="functions-sqljson-op-table"/> shows the operators and
17903 methods available in <type>jsonpath</type>. Note that while the unary
17904 operators and methods can be applied to multiple values resulting from a
17905 preceding path step, the binary operators (addition etc.) can only be
17906 applied to single values. In lax mode, methods applied to an array will be
17907 executed for each value in the array. The exceptions are
17908 <literal>.type()</literal> and <literal>.size()</literal>, which apply to
17909 the array itself.
17910 </para>
17912 <table id="functions-sqljson-op-table">
17913 <title><type>jsonpath</type> Operators and Methods</title>
17914 <tgroup cols="1">
17915 <thead>
17916 <row>
17917 <entry role="func_table_entry"><para role="func_signature">
17918 Operator/Method
17919 </para>
17920 <para>
17921 Description
17922 </para>
17923 <para>
17924 Example(s)
17925 </para></entry>
17926 </row>
17927 </thead>
17929 <tbody>
17930 <row>
17931 <entry role="func_table_entry"><para role="func_signature">
17932 <replaceable>number</replaceable> <literal>+</literal> <replaceable>number</replaceable>
17933 <returnvalue><replaceable>number</replaceable></returnvalue>
17934 </para>
17935 <para>
17936 Addition
17937 </para>
17938 <para>
17939 <literal>jsonb_path_query('[2]', '$[0] + 3')</literal>
17940 <returnvalue>5</returnvalue>
17941 </para></entry>
17942 </row>
17944 <row>
17945 <entry role="func_table_entry"><para role="func_signature">
17946 <literal>+</literal> <replaceable>number</replaceable>
17947 <returnvalue><replaceable>number</replaceable></returnvalue>
17948 </para>
17949 <para>
17950 Unary plus (no operation); unlike addition, this can iterate over
17951 multiple values
17952 </para>
17953 <para>
17954 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '+ $.x')</literal>
17955 <returnvalue>[2, 3, 4]</returnvalue>
17956 </para></entry>
17957 </row>
17959 <row>
17960 <entry role="func_table_entry"><para role="func_signature">
17961 <replaceable>number</replaceable> <literal>-</literal> <replaceable>number</replaceable>
17962 <returnvalue><replaceable>number</replaceable></returnvalue>
17963 </para>
17964 <para>
17965 Subtraction
17966 </para>
17967 <para>
17968 <literal>jsonb_path_query('[2]', '7 - $[0]')</literal>
17969 <returnvalue>5</returnvalue>
17970 </para></entry>
17971 </row>
17973 <row>
17974 <entry role="func_table_entry"><para role="func_signature">
17975 <literal>-</literal> <replaceable>number</replaceable>
17976 <returnvalue><replaceable>number</replaceable></returnvalue>
17977 </para>
17978 <para>
17979 Negation; unlike subtraction, this can iterate over
17980 multiple values
17981 </para>
17982 <para>
17983 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '- $.x')</literal>
17984 <returnvalue>[-2, -3, -4]</returnvalue>
17985 </para></entry>
17986 </row>
17988 <row>
17989 <entry role="func_table_entry"><para role="func_signature">
17990 <replaceable>number</replaceable> <literal>*</literal> <replaceable>number</replaceable>
17991 <returnvalue><replaceable>number</replaceable></returnvalue>
17992 </para>
17993 <para>
17994 Multiplication
17995 </para>
17996 <para>
17997 <literal>jsonb_path_query('[4]', '2 * $[0]')</literal>
17998 <returnvalue>8</returnvalue>
17999 </para></entry>
18000 </row>
18002 <row>
18003 <entry role="func_table_entry"><para role="func_signature">
18004 <replaceable>number</replaceable> <literal>/</literal> <replaceable>number</replaceable>
18005 <returnvalue><replaceable>number</replaceable></returnvalue>
18006 </para>
18007 <para>
18008 Division
18009 </para>
18010 <para>
18011 <literal>jsonb_path_query('[8.5]', '$[0] / 2')</literal>
18012 <returnvalue>4.2500000000000000</returnvalue>
18013 </para></entry>
18014 </row>
18016 <row>
18017 <entry role="func_table_entry"><para role="func_signature">
18018 <replaceable>number</replaceable> <literal>%</literal> <replaceable>number</replaceable>
18019 <returnvalue><replaceable>number</replaceable></returnvalue>
18020 </para>
18021 <para>
18022 Modulo (remainder)
18023 </para>
18024 <para>
18025 <literal>jsonb_path_query('[32]', '$[0] % 10')</literal>
18026 <returnvalue>2</returnvalue>
18027 </para></entry>
18028 </row>
18030 <row>
18031 <entry role="func_table_entry"><para role="func_signature">
18032 <replaceable>value</replaceable> <literal>.</literal> <literal>type()</literal>
18033 <returnvalue><replaceable>string</replaceable></returnvalue>
18034 </para>
18035 <para>
18036 Type of the JSON item (see <function>json_typeof</function>)
18037 </para>
18038 <para>
18039 <literal>jsonb_path_query_array('[1, "2", {}]', '$[*].type()')</literal>
18040 <returnvalue>["number", "string", "object"]</returnvalue>
18041 </para></entry>
18042 </row>
18044 <row>
18045 <entry role="func_table_entry"><para role="func_signature">
18046 <replaceable>value</replaceable> <literal>.</literal> <literal>size()</literal>
18047 <returnvalue><replaceable>number</replaceable></returnvalue>
18048 </para>
18049 <para>
18050 Size of the JSON item (number of array elements, or 1 if not an
18051 array)
18052 </para>
18053 <para>
18054 <literal>jsonb_path_query('{"m": [11, 15]}', '$.m.size()')</literal>
18055 <returnvalue>2</returnvalue>
18056 </para></entry>
18057 </row>
18059 <row>
18060 <entry role="func_table_entry"><para role="func_signature">
18061 <replaceable>value</replaceable> <literal>.</literal> <literal>boolean()</literal>
18062 <returnvalue><replaceable>boolean</replaceable></returnvalue>
18063 </para>
18064 <para>
18065 Boolean value converted from a JSON boolean, number, or string
18066 </para>
18067 <para>
18068 <literal>jsonb_path_query_array('[1, "yes", false]', '$[*].boolean()')</literal>
18069 <returnvalue>[true, true, false]</returnvalue>
18070 </para></entry>
18071 </row>
18073 <row>
18074 <entry role="func_table_entry"><para role="func_signature">
18075 <replaceable>value</replaceable> <literal>.</literal> <literal>string()</literal>
18076 <returnvalue><replaceable>string</replaceable></returnvalue>
18077 </para>
18078 <para>
18079 String value converted from a JSON boolean, number, string, or
18080 datetime
18081 </para>
18082 <para>
18083 <literal>jsonb_path_query_array('[1.23, "xyz", false]', '$[*].string()')</literal>
18084 <returnvalue>["1.23", "xyz", "false"]</returnvalue>
18085 </para>
18086 <para>
18087 <literal>jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp().string()')</literal>
18088 <returnvalue>"2023-08-15T12:34:56"</returnvalue>
18089 </para></entry>
18090 </row>
18092 <row>
18093 <entry role="func_table_entry"><para role="func_signature">
18094 <replaceable>value</replaceable> <literal>.</literal> <literal>double()</literal>
18095 <returnvalue><replaceable>number</replaceable></returnvalue>
18096 </para>
18097 <para>
18098 Approximate floating-point number converted from a JSON number or
18099 string
18100 </para>
18101 <para>
18102 <literal>jsonb_path_query('{"len": "1.9"}', '$.len.double() * 2')</literal>
18103 <returnvalue>3.8</returnvalue>
18104 </para></entry>
18105 </row>
18107 <row>
18108 <entry role="func_table_entry"><para role="func_signature">
18109 <replaceable>number</replaceable> <literal>.</literal> <literal>ceiling()</literal>
18110 <returnvalue><replaceable>number</replaceable></returnvalue>
18111 </para>
18112 <para>
18113 Nearest integer greater than or equal to the given number
18114 </para>
18115 <para>
18116 <literal>jsonb_path_query('{"h": 1.3}', '$.h.ceiling()')</literal>
18117 <returnvalue>2</returnvalue>
18118 </para></entry>
18119 </row>
18121 <row>
18122 <entry role="func_table_entry"><para role="func_signature">
18123 <replaceable>number</replaceable> <literal>.</literal> <literal>floor()</literal>
18124 <returnvalue><replaceable>number</replaceable></returnvalue>
18125 </para>
18126 <para>
18127 Nearest integer less than or equal to the given number
18128 </para>
18129 <para>
18130 <literal>jsonb_path_query('{"h": 1.7}', '$.h.floor()')</literal>
18131 <returnvalue>1</returnvalue>
18132 </para></entry>
18133 </row>
18135 <row>
18136 <entry role="func_table_entry"><para role="func_signature">
18137 <replaceable>number</replaceable> <literal>.</literal> <literal>abs()</literal>
18138 <returnvalue><replaceable>number</replaceable></returnvalue>
18139 </para>
18140 <para>
18141 Absolute value of the given number
18142 </para>
18143 <para>
18144 <literal>jsonb_path_query('{"z": -0.3}', '$.z.abs()')</literal>
18145 <returnvalue>0.3</returnvalue>
18146 </para></entry>
18147 </row>
18149 <row>
18150 <entry role="func_table_entry"><para role="func_signature">
18151 <replaceable>value</replaceable> <literal>.</literal> <literal>bigint()</literal>
18152 <returnvalue><replaceable>bigint</replaceable></returnvalue>
18153 </para>
18154 <para>
18155 Big integer value converted from a JSON number or string
18156 </para>
18157 <para>
18158 <literal>jsonb_path_query('{"len": "9876543219"}', '$.len.bigint()')</literal>
18159 <returnvalue>9876543219</returnvalue>
18160 </para></entry>
18161 </row>
18163 <row>
18164 <entry role="func_table_entry"><para role="func_signature">
18165 <replaceable>value</replaceable> <literal>.</literal> <literal>decimal( [ <replaceable>precision</replaceable> [ , <replaceable>scale</replaceable> ] ] )</literal>
18166 <returnvalue><replaceable>decimal</replaceable></returnvalue>
18167 </para>
18168 <para>
18169 Rounded decimal value converted from a JSON number or string
18170 (<literal>precision</literal> and <literal>scale</literal> must be
18171 integer values)
18172 </para>
18173 <para>
18174 <literal>jsonb_path_query('1234.5678', '$.decimal(6, 2)')</literal>
18175 <returnvalue>1234.57</returnvalue>
18176 </para></entry>
18177 </row>
18179 <row>
18180 <entry role="func_table_entry"><para role="func_signature">
18181 <replaceable>value</replaceable> <literal>.</literal> <literal>integer()</literal>
18182 <returnvalue><replaceable>integer</replaceable></returnvalue>
18183 </para>
18184 <para>
18185 Integer value converted from a JSON number or string
18186 </para>
18187 <para>
18188 <literal>jsonb_path_query('{"len": "12345"}', '$.len.integer()')</literal>
18189 <returnvalue>12345</returnvalue>
18190 </para></entry>
18191 </row>
18193 <row>
18194 <entry role="func_table_entry"><para role="func_signature">
18195 <replaceable>value</replaceable> <literal>.</literal> <literal>number()</literal>
18196 <returnvalue><replaceable>numeric</replaceable></returnvalue>
18197 </para>
18198 <para>
18199 Numeric value converted from a JSON number or string
18200 </para>
18201 <para>
18202 <literal>jsonb_path_query('{"len": "123.45"}', '$.len.number()')</literal>
18203 <returnvalue>123.45</returnvalue>
18204 </para></entry>
18205 </row>
18207 <row>
18208 <entry role="func_table_entry"><para role="func_signature">
18209 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime()</literal>
18210 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
18211 (see note)
18212 </para>
18213 <para>
18214 Date/time value converted from a string
18215 </para>
18216 <para>
18217 <literal>jsonb_path_query('["2015-8-1", "2015-08-12"]', '$[*] ? (@.datetime() &lt; "2015-08-2".datetime())')</literal>
18218 <returnvalue>"2015-8-1"</returnvalue>
18219 </para></entry>
18220 </row>
18222 <row>
18223 <entry role="func_table_entry"><para role="func_signature">
18224 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime(<replaceable>template</replaceable>)</literal>
18225 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
18226 (see note)
18227 </para>
18228 <para>
18229 Date/time value converted from a string using the
18230 specified <function>to_timestamp</function> template
18231 </para>
18232 <para>
18233 <literal>jsonb_path_query_array('["12:30", "18:40"]', '$[*].datetime("HH24:MI")')</literal>
18234 <returnvalue>["12:30:00", "18:40:00"]</returnvalue>
18235 </para></entry>
18236 </row>
18238 <row>
18239 <entry role="func_table_entry"><para role="func_signature">
18240 <replaceable>string</replaceable> <literal>.</literal> <literal>date()</literal>
18241 <returnvalue><replaceable>date</replaceable></returnvalue>
18242 </para>
18243 <para>
18244 Date value converted from a string
18245 </para>
18246 <para>
18247 <literal>jsonb_path_query('"2023-08-15"', '$.date()')</literal>
18248 <returnvalue>"2023-08-15"</returnvalue>
18249 </para></entry>
18250 </row>
18252 <row>
18253 <entry role="func_table_entry"><para role="func_signature">
18254 <replaceable>string</replaceable> <literal>.</literal> <literal>time()</literal>
18255 <returnvalue><replaceable>time without time zone</replaceable></returnvalue>
18256 </para>
18257 <para>
18258 Time without time zone value converted from a string
18259 </para>
18260 <para>
18261 <literal>jsonb_path_query('"12:34:56"', '$.time()')</literal>
18262 <returnvalue>"12:34:56"</returnvalue>
18263 </para></entry>
18264 </row>
18266 <row>
18267 <entry role="func_table_entry"><para role="func_signature">
18268 <replaceable>string</replaceable> <literal>.</literal> <literal>time(<replaceable>precision</replaceable>)</literal>
18269 <returnvalue><replaceable>time without time zone</replaceable></returnvalue>
18270 </para>
18271 <para>
18272 Time without time zone value converted from a string, with fractional
18273 seconds adjusted to the given precision
18274 </para>
18275 <para>
18276 <literal>jsonb_path_query('"12:34:56.789"', '$.time(2)')</literal>
18277 <returnvalue>"12:34:56.79"</returnvalue>
18278 </para></entry>
18279 </row>
18281 <row>
18282 <entry role="func_table_entry"><para role="func_signature">
18283 <replaceable>string</replaceable> <literal>.</literal> <literal>time_tz()</literal>
18284 <returnvalue><replaceable>time with time zone</replaceable></returnvalue>
18285 </para>
18286 <para>
18287 Time with time zone value converted from a string
18288 </para>
18289 <para>
18290 <literal>jsonb_path_query('"12:34:56 +05:30"', '$.time_tz()')</literal>
18291 <returnvalue>"12:34:56+05:30"</returnvalue>
18292 </para></entry>
18293 </row>
18295 <row>
18296 <entry role="func_table_entry"><para role="func_signature">
18297 <replaceable>string</replaceable> <literal>.</literal> <literal>time_tz(<replaceable>precision</replaceable>)</literal>
18298 <returnvalue><replaceable>time with time zone</replaceable></returnvalue>
18299 </para>
18300 <para>
18301 Time with time zone value converted from a string, with fractional
18302 seconds adjusted to the given precision
18303 </para>
18304 <para>
18305 <literal>jsonb_path_query('"12:34:56.789 +05:30"', '$.time_tz(2)')</literal>
18306 <returnvalue>"12:34:56.79+05:30"</returnvalue>
18307 </para></entry>
18308 </row>
18310 <row>
18311 <entry role="func_table_entry"><para role="func_signature">
18312 <replaceable>string</replaceable> <literal>.</literal> <literal>timestamp()</literal>
18313 <returnvalue><replaceable>timestamp without time zone</replaceable></returnvalue>
18314 </para>
18315 <para>
18316 Timestamp without time zone value converted from a string
18317 </para>
18318 <para>
18319 <literal>jsonb_path_query('"2023-08-15 12:34:56"', '$.timestamp()')</literal>
18320 <returnvalue>"2023-08-15T12:34:56"</returnvalue>
18321 </para></entry>
18322 </row>
18324 <row>
18325 <entry role="func_table_entry"><para role="func_signature">
18326 <replaceable>string</replaceable> <literal>.</literal> <literal>timestamp(<replaceable>precision</replaceable>)</literal>
18327 <returnvalue><replaceable>timestamp without time zone</replaceable></returnvalue>
18328 </para>
18329 <para>
18330 Timestamp without time zone value converted from a string, with
18331 fractional seconds adjusted to the given precision
18332 </para>
18333 <para>
18334 <literal>jsonb_path_query('"2023-08-15 12:34:56.789"', '$.timestamp(2)')</literal>
18335 <returnvalue>"2023-08-15T12:34:56.79"</returnvalue>
18336 </para></entry>
18337 </row>
18339 <row>
18340 <entry role="func_table_entry"><para role="func_signature">
18341 <replaceable>string</replaceable> <literal>.</literal> <literal>timestamp_tz()</literal>
18342 <returnvalue><replaceable>timestamp with time zone</replaceable></returnvalue>
18343 </para>
18344 <para>
18345 Timestamp with time zone value converted from a string
18346 </para>
18347 <para>
18348 <literal>jsonb_path_query('"2023-08-15 12:34:56 +05:30"', '$.timestamp_tz()')</literal>
18349 <returnvalue>"2023-08-15T12:34:56+05:30"</returnvalue>
18350 </para></entry>
18351 </row>
18353 <row>
18354 <entry role="func_table_entry"><para role="func_signature">
18355 <replaceable>string</replaceable> <literal>.</literal> <literal>timestamp_tz(<replaceable>precision</replaceable>)</literal>
18356 <returnvalue><replaceable>timestamp with time zone</replaceable></returnvalue>
18357 </para>
18358 <para>
18359 Timestamp with time zone value converted from a string, with fractional
18360 seconds adjusted to the given precision
18361 </para>
18362 <para>
18363 <literal>jsonb_path_query('"2023-08-15 12:34:56.789 +05:30"', '$.timestamp_tz(2)')</literal>
18364 <returnvalue>"2023-08-15T12:34:56.79+05:30"</returnvalue>
18365 </para></entry>
18366 </row>
18368 <row>
18369 <entry role="func_table_entry"><para role="func_signature">
18370 <replaceable>object</replaceable> <literal>.</literal> <literal>keyvalue()</literal>
18371 <returnvalue><replaceable>array</replaceable></returnvalue>
18372 </para>
18373 <para>
18374 The object's key-value pairs, represented as an array of objects
18375 containing three fields: <literal>"key"</literal>,
18376 <literal>"value"</literal>, and <literal>"id"</literal>;
18377 <literal>"id"</literal> is a unique identifier of the object the
18378 key-value pair belongs to
18379 </para>
18380 <para>
18381 <literal>jsonb_path_query_array('{"x": "20", "y": 32}', '$.keyvalue()')</literal>
18382 <returnvalue>[{"id": 0, "key": "x", "value": "20"}, {"id": 0, "key": "y", "value": 32}]</returnvalue>
18383 </para></entry>
18384 </row>
18385 </tbody>
18386 </tgroup>
18387 </table>
18389 <note>
18390 <para>
18391 The result type of the <literal>datetime()</literal> and
18392 <literal>datetime(<replaceable>template</replaceable>)</literal>
18393 methods can be <type>date</type>, <type>timetz</type>, <type>time</type>,
18394 <type>timestamptz</type>, or <type>timestamp</type>.
18395 Both methods determine their result type dynamically.
18396 </para>
18397 <para>
18398 The <literal>datetime()</literal> method sequentially tries to
18399 match its input string to the ISO formats
18400 for <type>date</type>, <type>timetz</type>, <type>time</type>,
18401 <type>timestamptz</type>, and <type>timestamp</type>. It stops on
18402 the first matching format and emits the corresponding data type.
18403 </para>
18404 <para>
18405 The <literal>datetime(<replaceable>template</replaceable>)</literal>
18406 method determines the result type according to the fields used in the
18407 provided template string.
18408 </para>
18409 <para>
18410 The <literal>datetime()</literal> and
18411 <literal>datetime(<replaceable>template</replaceable>)</literal> methods
18412 use the same parsing rules as the <literal>to_timestamp</literal> SQL
18413 function does (see <xref linkend="functions-formatting"/>), with three
18414 exceptions. First, these methods don't allow unmatched template
18415 patterns. Second, only the following separators are allowed in the
18416 template string: minus sign, period, solidus (slash), comma, apostrophe,
18417 semicolon, colon and space. Third, separators in the template string
18418 must exactly match the input string.
18419 </para>
18420 <para>
18421 If different date/time types need to be compared, an implicit cast is
18422 applied. A <type>date</type> value can be cast to <type>timestamp</type>
18423 or <type>timestamptz</type>, <type>timestamp</type> can be cast to
18424 <type>timestamptz</type>, and <type>time</type> to <type>timetz</type>.
18425 However, all but the first of these conversions depend on the current
18426 <xref linkend="guc-timezone"/> setting, and thus can only be performed
18427 within timezone-aware <type>jsonpath</type> functions. Similarly, other
18428 date/time-related methods that convert strings to date/time types
18429 also do this casting, which may involve the current
18430 <xref linkend="guc-timezone"/> setting. Therefore, these conversions can
18431 also only be performed within timezone-aware <type>jsonpath</type>
18432 functions.
18433 </para>
18434 </note>
18436 <para>
18437 <xref linkend="functions-sqljson-filter-ex-table"/> shows the available
18438 filter expression elements.
18439 </para>
18441 <table id="functions-sqljson-filter-ex-table">
18442 <title><type>jsonpath</type> Filter Expression Elements</title>
18443 <tgroup cols="1">
18444 <thead>
18445 <row>
18446 <entry role="func_table_entry"><para role="func_signature">
18447 Predicate/Value
18448 </para>
18449 <para>
18450 Description
18451 </para>
18452 <para>
18453 Example(s)
18454 </para></entry>
18455 </row>
18456 </thead>
18458 <tbody>
18459 <row>
18460 <entry role="func_table_entry"><para role="func_signature">
18461 <replaceable>value</replaceable> <literal>==</literal> <replaceable>value</replaceable>
18462 <returnvalue>boolean</returnvalue>
18463 </para>
18464 <para>
18465 Equality comparison (this, and the other comparison operators, work on
18466 all JSON scalar values)
18467 </para>
18468 <para>
18469 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == 1)')</literal>
18470 <returnvalue>[1, 1]</returnvalue>
18471 </para>
18472 <para>
18473 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == "a")')</literal>
18474 <returnvalue>["a"]</returnvalue>
18475 </para></entry>
18476 </row>
18478 <row>
18479 <entry role="func_table_entry"><para role="func_signature">
18480 <replaceable>value</replaceable> <literal>!=</literal> <replaceable>value</replaceable>
18481 <returnvalue>boolean</returnvalue>
18482 </para>
18483 <para role="func_signature">
18484 <replaceable>value</replaceable> <literal>&lt;&gt;</literal> <replaceable>value</replaceable>
18485 <returnvalue>boolean</returnvalue>
18486 </para>
18487 <para>
18488 Non-equality comparison
18489 </para>
18490 <para>
18491 <literal>jsonb_path_query_array('[1, 2, 1, 3]', '$[*] ? (@ != 1)')</literal>
18492 <returnvalue>[2, 3]</returnvalue>
18493 </para>
18494 <para>
18495 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;&gt; "b")')</literal>
18496 <returnvalue>["a", "c"]</returnvalue>
18497 </para></entry>
18498 </row>
18500 <row>
18501 <entry role="func_table_entry"><para role="func_signature">
18502 <replaceable>value</replaceable> <literal>&lt;</literal> <replaceable>value</replaceable>
18503 <returnvalue>boolean</returnvalue>
18504 </para>
18505 <para>
18506 Less-than comparison
18507 </para>
18508 <para>
18509 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &lt; 2)')</literal>
18510 <returnvalue>[1]</returnvalue>
18511 </para></entry>
18512 </row>
18514 <row>
18515 <entry role="func_table_entry"><para role="func_signature">
18516 <replaceable>value</replaceable> <literal>&lt;=</literal> <replaceable>value</replaceable>
18517 <returnvalue>boolean</returnvalue>
18518 </para>
18519 <para>
18520 Less-than-or-equal-to comparison
18521 </para>
18522 <para>
18523 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;= "b")')</literal>
18524 <returnvalue>["a", "b"]</returnvalue>
18525 </para></entry>
18526 </row>
18528 <row>
18529 <entry role="func_table_entry"><para role="func_signature">
18530 <replaceable>value</replaceable> <literal>&gt;</literal> <replaceable>value</replaceable>
18531 <returnvalue>boolean</returnvalue>
18532 </para>
18533 <para>
18534 Greater-than comparison
18535 </para>
18536 <para>
18537 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt; 2)')</literal>
18538 <returnvalue>[3]</returnvalue>
18539 </para></entry>
18540 </row>
18542 <row>
18543 <entry role="func_table_entry"><para role="func_signature">
18544 <replaceable>value</replaceable> <literal>&gt;=</literal> <replaceable>value</replaceable>
18545 <returnvalue>boolean</returnvalue>
18546 </para>
18547 <para>
18548 Greater-than-or-equal-to comparison
18549 </para>
18550 <para>
18551 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt;= 2)')</literal>
18552 <returnvalue>[2, 3]</returnvalue>
18553 </para></entry>
18554 </row>
18556 <row>
18557 <entry role="func_table_entry"><para role="func_signature">
18558 <literal>true</literal>
18559 <returnvalue>boolean</returnvalue>
18560 </para>
18561 <para>
18562 JSON constant <literal>true</literal>
18563 </para>
18564 <para>
18565 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == true)')</literal>
18566 <returnvalue>{"name": "Chris", "parent": true}</returnvalue>
18567 </para></entry>
18568 </row>
18570 <row>
18571 <entry role="func_table_entry"><para role="func_signature">
18572 <literal>false</literal>
18573 <returnvalue>boolean</returnvalue>
18574 </para>
18575 <para>
18576 JSON constant <literal>false</literal>
18577 </para>
18578 <para>
18579 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == false)')</literal>
18580 <returnvalue>{"name": "John", "parent": false}</returnvalue>
18581 </para></entry>
18582 </row>
18584 <row>
18585 <entry role="func_table_entry"><para role="func_signature">
18586 <literal>null</literal>
18587 <returnvalue><replaceable>value</replaceable></returnvalue>
18588 </para>
18589 <para>
18590 JSON constant <literal>null</literal> (note that, unlike in SQL,
18591 comparison to <literal>null</literal> works normally)
18592 </para>
18593 <para>
18594 <literal>jsonb_path_query('[{"name": "Mary", "job": null}, {"name": "Michael", "job": "driver"}]', '$[*] ? (@.job == null) .name')</literal>
18595 <returnvalue>"Mary"</returnvalue>
18596 </para></entry>
18597 </row>
18599 <row>
18600 <entry role="func_table_entry"><para role="func_signature">
18601 <replaceable>boolean</replaceable> <literal>&amp;&amp;</literal> <replaceable>boolean</replaceable>
18602 <returnvalue>boolean</returnvalue>
18603 </para>
18604 <para>
18605 Boolean AND
18606 </para>
18607 <para>
18608 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &gt; 1 &amp;&amp; @ &lt; 5)')</literal>
18609 <returnvalue>3</returnvalue>
18610 </para></entry>
18611 </row>
18613 <row>
18614 <entry role="func_table_entry"><para role="func_signature">
18615 <replaceable>boolean</replaceable> <literal>||</literal> <replaceable>boolean</replaceable>
18616 <returnvalue>boolean</returnvalue>
18617 </para>
18618 <para>
18619 Boolean OR
18620 </para>
18621 <para>
18622 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &lt; 1 || @ &gt; 5)')</literal>
18623 <returnvalue>7</returnvalue>
18624 </para></entry>
18625 </row>
18627 <row>
18628 <entry role="func_table_entry"><para role="func_signature">
18629 <literal>!</literal> <replaceable>boolean</replaceable>
18630 <returnvalue>boolean</returnvalue>
18631 </para>
18632 <para>
18633 Boolean NOT
18634 </para>
18635 <para>
18636 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (!(@ &lt; 5))')</literal>
18637 <returnvalue>7</returnvalue>
18638 </para></entry>
18639 </row>
18641 <row>
18642 <entry role="func_table_entry"><para role="func_signature">
18643 <replaceable>boolean</replaceable> <literal>is unknown</literal>
18644 <returnvalue>boolean</returnvalue>
18645 </para>
18646 <para>
18647 Tests whether a Boolean condition is <literal>unknown</literal>.
18648 </para>
18649 <para>
18650 <literal>jsonb_path_query('[-1, 2, 7, "foo"]', '$[*] ? ((@ > 0) is unknown)')</literal>
18651 <returnvalue>"foo"</returnvalue>
18652 </para></entry>
18653 </row>
18655 <row>
18656 <entry role="func_table_entry"><para role="func_signature">
18657 <replaceable>string</replaceable> <literal>like_regex</literal> <replaceable>string</replaceable> <optional> <literal>flag</literal> <replaceable>string</replaceable> </optional>
18658 <returnvalue>boolean</returnvalue>
18659 </para>
18660 <para>
18661 Tests whether the first operand matches the regular expression
18662 given by the second operand, optionally with modifications
18663 described by a string of <literal>flag</literal> characters (see
18664 <xref linkend="jsonpath-regular-expressions"/>).
18665 </para>
18666 <para>
18667 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c")')</literal>
18668 <returnvalue>["abc", "abdacb"]</returnvalue>
18669 </para>
18670 <para>
18671 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c" flag "i")')</literal>
18672 <returnvalue>["abc", "aBdC", "abdacb"]</returnvalue>
18673 </para></entry>
18674 </row>
18676 <row>
18677 <entry role="func_table_entry"><para role="func_signature">
18678 <replaceable>string</replaceable> <literal>starts with</literal> <replaceable>string</replaceable>
18679 <returnvalue>boolean</returnvalue>
18680 </para>
18681 <para>
18682 Tests whether the second operand is an initial substring of the first
18683 operand.
18684 </para>
18685 <para>
18686 <literal>jsonb_path_query('["John Smith", "Mary Stone", "Bob Johnson"]', '$[*] ? (@ starts with "John")')</literal>
18687 <returnvalue>"John Smith"</returnvalue>
18688 </para></entry>
18689 </row>
18691 <row>
18692 <entry role="func_table_entry"><para role="func_signature">
18693 <literal>exists</literal> <literal>(</literal> <replaceable>path_expression</replaceable> <literal>)</literal>
18694 <returnvalue>boolean</returnvalue>
18695 </para>
18696 <para>
18697 Tests whether a path expression matches at least one SQL/JSON item.
18698 Returns <literal>unknown</literal> if the path expression would result
18699 in an error; the second example uses this to avoid a no-such-key error
18700 in strict mode.
18701 </para>
18702 <para>
18703 <literal>jsonb_path_query('{"x": [1, 2], "y": [2, 4]}', 'strict $.* ? (exists (@ ? (@[*] &gt; 2)))')</literal>
18704 <returnvalue>[2, 4]</returnvalue>
18705 </para>
18706 <para>
18707 <literal>jsonb_path_query_array('{"value": 41}', 'strict $ ? (exists (@.name)) .name')</literal>
18708 <returnvalue>[]</returnvalue>
18709 </para></entry>
18710 </row>
18711 </tbody>
18712 </tgroup>
18713 </table>
18715 </sect3>
18717 <sect3 id="jsonpath-regular-expressions">
18718 <title>SQL/JSON Regular Expressions</title>
18720 <indexterm zone="jsonpath-regular-expressions">
18721 <primary><literal>LIKE_REGEX</literal></primary>
18722 <secondary>in SQL/JSON</secondary>
18723 </indexterm>
18725 <para>
18726 SQL/JSON path expressions allow matching text to a regular expression
18727 with the <literal>like_regex</literal> filter. For example, the
18728 following SQL/JSON path query would case-insensitively match all
18729 strings in an array that start with an English vowel:
18730 <programlisting>
18731 $[*] ? (@ like_regex "^[aeiou]" flag "i")
18732 </programlisting>
18733 </para>
18735 <para>
18736 The optional <literal>flag</literal> string may include one or more of
18737 the characters
18738 <literal>i</literal> for case-insensitive match,
18739 <literal>m</literal> to allow <literal>^</literal>
18740 and <literal>$</literal> to match at newlines,
18741 <literal>s</literal> to allow <literal>.</literal> to match a newline,
18742 and <literal>q</literal> to quote the whole pattern (reducing the
18743 behavior to a simple substring match).
18744 </para>
18746 <para>
18747 The SQL/JSON standard borrows its definition for regular expressions
18748 from the <literal>LIKE_REGEX</literal> operator, which in turn uses the
18749 XQuery standard. PostgreSQL does not currently support the
18750 <literal>LIKE_REGEX</literal> operator. Therefore,
18751 the <literal>like_regex</literal> filter is implemented using the
18752 POSIX regular expression engine described in
18753 <xref linkend="functions-posix-regexp"/>. This leads to various minor
18754 discrepancies from standard SQL/JSON behavior, which are cataloged in
18755 <xref linkend="posix-vs-xquery"/>.
18756 Note, however, that the flag-letter incompatibilities described there
18757 do not apply to SQL/JSON, as it translates the XQuery flag letters to
18758 match what the POSIX engine expects.
18759 </para>
18761 <para>
18762 Keep in mind that the pattern argument of <literal>like_regex</literal>
18763 is a JSON path string literal, written according to the rules given in
18764 <xref linkend="datatype-jsonpath"/>. This means in particular that any
18765 backslashes you want to use in the regular expression must be doubled.
18766 For example, to match string values of the root document that contain
18767 only digits:
18768 <programlisting>
18769 $.* ? (@ like_regex "^\\d+$")
18770 </programlisting>
18771 </para>
18772 </sect3>
18773 </sect2>
18775 <sect2 id="sqljson-query-functions">
18776 <title>SQL/JSON Query Functions</title>
18777 <para>
18778 SQL/JSON functions <literal>JSON_EXISTS()</literal>,
18779 <literal>JSON_QUERY()</literal>, and <literal>JSON_VALUE()</literal>
18780 described in <xref linkend="functions-sqljson-querying"/> can be used
18781 to query JSON documents. Each of these functions apply a
18782 <replaceable>path_expression</replaceable> (an SQL/JSON path query) to a
18783 <replaceable>context_item</replaceable> (the document). See
18784 <xref linkend="functions-sqljson-path"/> for more details on what
18785 the <replaceable>path_expression</replaceable> can contain. The
18786 <replaceable>path_expression</replaceable> can also reference variables,
18787 whose values are specified with their respective names in the
18788 <literal>PASSING</literal> clause that is supported by each function.
18789 <replaceable>context_item</replaceable> can be a <type>jsonb</type> value
18790 or a character string that can be successfully cast to <type>jsonb</type>.
18791 </para>
18793 <table id="functions-sqljson-querying">
18794 <title>SQL/JSON Query Functions</title>
18795 <tgroup cols="1">
18796 <thead>
18797 <row>
18798 <entry role="func_table_entry"><para role="func_signature">
18799 Function signature
18800 </para>
18801 <para>
18802 Description
18803 </para>
18804 <para>
18805 Example(s)
18806 </para></entry>
18807 </row>
18808 </thead>
18809 <tbody>
18810 <row>
18811 <entry role="func_table_entry"><para role="func_signature">
18812 <indexterm><primary>json_exists</primary></indexterm>
18813 <synopsis>
18814 <function>JSON_EXISTS</function> (
18815 <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
18816 <optional> <literal>PASSING</literal> { <replaceable>value</replaceable> <literal>AS</literal> <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
18817 <optional>{ <literal>TRUE</literal> | <literal>FALSE</literal> |<literal> UNKNOWN</literal> | <literal>ERROR</literal> } <literal>ON ERROR</literal> </optional>) <returnvalue>boolean</returnvalue>
18818 </synopsis>
18819 </para>
18820 <itemizedlist>
18821 <listitem>
18822 <para>
18823 Returns true if the SQL/JSON <replaceable>path_expression</replaceable>
18824 applied to the <replaceable>context_item</replaceable> yields any
18825 items, false otherwise.
18826 </para>
18827 </listitem>
18828 <listitem>
18829 <para>
18830 The <literal>ON ERROR</literal> clause specifies the behavior if
18831 an error occurs during <replaceable>path_expression</replaceable>
18832 evaluation. Specifying <literal>ERROR</literal> will cause an error to
18833 be thrown with the appropriate message. Other options include
18834 returning <type>boolean</type> values <literal>FALSE</literal> or
18835 <literal>TRUE</literal> or the value <literal>UNKNOWN</literal> which
18836 is actually an SQL NULL. The default when no <literal>ON ERROR</literal>
18837 clause is specified is to return the <type>boolean</type> value
18838 <literal>FALSE</literal>.
18839 </para>
18840 </listitem>
18841 </itemizedlist>
18842 <para>
18843 Examples:
18844 </para>
18845 <para>
18846 <literal>JSON_EXISTS(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > $x)' PASSING 2 AS x)</literal>
18847 <returnvalue>t</returnvalue>
18848 </para>
18849 <para>
18850 <literal>JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR)</literal>
18851 <returnvalue>f</returnvalue>
18852 </para>
18853 <para>
18854 <literal>JSON_EXISTS(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR)</literal>
18855 <returnvalue></returnvalue>
18856 <programlisting>
18857 ERROR: jsonpath array subscript is out of bounds
18858 </programlisting>
18859 </para></entry>
18860 </row>
18861 <row>
18862 <entry role="func_table_entry"><para role="func_signature">
18863 <indexterm><primary>json_query</primary></indexterm>
18864 <synopsis>
18865 <function>JSON_QUERY</function> (
18866 <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
18867 <optional> <literal>PASSING</literal> { <replaceable>value</replaceable> <literal>AS</literal> <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
18868 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>
18869 <optional> { <literal>WITHOUT</literal> | <literal>WITH</literal> { <literal>CONDITIONAL</literal> | <optional><literal>UNCONDITIONAL</literal></optional> } } <optional> <literal>ARRAY</literal> </optional> <literal>WRAPPER</literal> </optional>
18870 <optional> { <literal>KEEP</literal> | <literal>OMIT</literal> } <literal>QUOTES</literal> <optional> <literal>ON SCALAR STRING</literal> </optional> </optional>
18871 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>EMPTY</literal> { <optional> <literal>ARRAY</literal> </optional> | <literal>OBJECT</literal> } | <literal>DEFAULT</literal> <replaceable>expression</replaceable> } <literal>ON EMPTY</literal> </optional>
18872 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>EMPTY</literal> { <optional> <literal>ARRAY</literal> </optional> | <literal>OBJECT</literal> } | <literal>DEFAULT</literal> <replaceable>expression</replaceable> } <literal>ON ERROR</literal> </optional>) <returnvalue>jsonb</returnvalue>
18873 </synopsis>
18874 </para>
18875 <itemizedlist>
18876 <listitem>
18877 <para>
18878 Returns the result of applying the SQL/JSON
18879 <replaceable>path_expression</replaceable> to the
18880 <replaceable>context_item</replaceable>.
18881 </para>
18882 </listitem>
18883 <listitem>
18884 <para>
18885 By default, the result is returned as a value of type <type>jsonb</type>,
18886 though the <literal>RETURNING</literal> clause can be used to return
18887 as some other type to which it can be successfully coerced.
18888 </para>
18889 </listitem>
18890 <listitem>
18891 <para>
18892 If the path expression may return multiple values, it might be necessary
18893 to wrap those values using the <literal>WITH WRAPPER</literal> clause to
18894 make it a valid JSON string, because the default behavior is to not wrap
18895 them, as if <literal>WITHOUT WRAPPER</literal> were specified. The
18896 <literal>WITH WRAPPER</literal> clause is by default taken to mean
18897 <literal>WITH UNCONDITIONAL WRAPPER</literal>, which means that even a
18898 single result value will be wrapped. To apply the wrapper only when
18899 multiple values are present, specify <literal>WITH CONDITIONAL WRAPPER</literal>.
18900 Getting multiple values in result will be treated as an error if
18901 <literal>WITHOUT WRAPPER</literal> is specified.
18902 </para>
18903 </listitem>
18904 <listitem>
18905 <para>
18906 If the result is a scalar string, by default, the returned value will
18907 be surrounded by quotes, making it a valid JSON value. It can be made
18908 explicit by specifying <literal>KEEP QUOTES</literal>. Conversely,
18909 quotes can be omitted by specifying <literal>OMIT QUOTES</literal>.
18910 To ensure that the result is a valid JSON value, <literal>OMIT QUOTES</literal>
18911 cannot be specified when <literal>WITH WRAPPER</literal> is also
18912 specified.
18913 </para>
18914 </listitem>
18915 <listitem>
18916 <para>
18917 The <literal>ON EMPTY</literal> clause specifies the behavior if
18918 evaluating <replaceable>path_expression</replaceable> yields an empty
18919 set. The <literal>ON ERROR</literal> clause specifies the behavior
18920 if an error occurs when evaluating <replaceable>path_expression</replaceable>,
18921 when coercing the result value to the <literal>RETURNING</literal> type,
18922 or when evaluating the <literal>ON EMPTY</literal> expression if the
18923 <replaceable>path_expression</replaceable> evaluation returns an empty
18924 set.
18925 </para>
18926 </listitem>
18927 <listitem>
18928 <para>
18929 For both <literal>ON EMPTY</literal> and <literal>ON ERROR</literal>,
18930 specifying <literal>ERROR</literal> will cause an error to be thrown with
18931 the appropriate message. Other options include returning an SQL NULL, an
18932 empty array (<literal>EMPTY <optional>ARRAY</optional></literal>),
18933 an empty object (<literal>EMPTY OBJECT</literal>), or a user-specified
18934 expression (<literal>DEFAULT</literal> <replaceable>expression</replaceable>)
18935 that can be coerced to jsonb or the type specified in <literal>RETURNING</literal>.
18936 The default when <literal>ON EMPTY</literal> or <literal>ON ERROR</literal>
18937 is not specified is to return an SQL NULL value.
18938 </para>
18939 </listitem>
18940 </itemizedlist>
18941 <para>
18942 Examples:
18943 </para>
18944 <para>
18945 <literal>JSON_QUERY(jsonb '[1,[2,3],null]', 'lax $[*][$off]' PASSING 1 AS off WITH CONDITIONAL WRAPPER)</literal>
18946 <returnvalue>3</returnvalue>
18947 </para>
18948 <para>
18949 <literal>JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' OMIT QUOTES)</literal>
18950 <returnvalue>[1, 2]</returnvalue>
18951 </para>
18952 <para>
18953 <literal>JSON_QUERY(jsonb '{"a": "[1, 2]"}', 'lax $.a' RETURNING int[] OMIT QUOTES ERROR ON ERROR)</literal>
18954 <returnvalue></returnvalue>
18955 <programlisting>
18956 ERROR: malformed array literal: "[1, 2]"
18957 DETAIL: Missing "]" after array dimensions.
18958 </programlisting>
18959 </para>
18960 </entry>
18961 </row>
18962 <row>
18963 <entry role="func_table_entry"><para role="func_signature">
18964 <indexterm><primary>json_value</primary></indexterm>
18965 <synopsis>
18966 <function>JSON_VALUE</function> (
18967 <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable>
18968 <optional> <literal>PASSING</literal> { <replaceable>value</replaceable> <literal>AS</literal> <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
18969 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> </optional>
18970 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>DEFAULT</literal> <replaceable>expression</replaceable> } <literal>ON EMPTY</literal> </optional>
18971 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>DEFAULT</literal> <replaceable>expression</replaceable> } <literal>ON ERROR</literal> </optional>) <returnvalue>text</returnvalue>
18972 </synopsis>
18973 </para>
18974 <itemizedlist>
18975 <listitem>
18976 <para>
18977 Returns the result of applying the SQL/JSON
18978 <replaceable>path_expression</replaceable> to the
18979 <replaceable>context_item</replaceable>.
18980 </para>
18981 </listitem>
18982 <listitem>
18983 <para>
18984 Only use <function>JSON_VALUE()</function> if the extracted value is
18985 expected to be a single <acronym>SQL/JSON</acronym> scalar item;
18986 getting multiple values will be treated as an error. If you expect that
18987 extracted value might be an object or an array, use the
18988 <function>JSON_QUERY</function> function instead.
18989 </para>
18990 </listitem>
18991 <listitem>
18992 <para>
18993 By default, the result, which must be a single scalar value, is
18994 returned as a value of type <type>text</type>, though the
18995 <literal>RETURNING</literal> clause can be used to return as some
18996 other type to which it can be successfully coerced.
18997 </para>
18998 </listitem>
18999 <listitem>
19000 <para>
19001 The <literal>ON ERROR</literal> and <literal>ON EMPTY</literal>
19002 clauses have similar semantics as mentioned in the description of
19003 <function>JSON_QUERY</function>, except the set of values returned in
19004 lieu of throwing an error is different.
19005 </para>
19006 </listitem>
19007 <listitem>
19008 <para>
19009 Note that scalar strings returned by <function>JSON_VALUE</function>
19010 always have their quotes removed, equivalent to specifying
19011 <literal>OMIT QUOTES</literal> in <function>JSON_QUERY</function>.
19012 </para>
19013 </listitem>
19014 </itemizedlist>
19015 <para>
19016 Examples:
19017 </para>
19018 <para>
19019 <literal>JSON_VALUE(jsonb '"123.45"', '$' RETURNING float)</literal>
19020 <returnvalue>123.45</returnvalue>
19021 </para>
19022 <para>
19023 <literal>JSON_VALUE(jsonb '"03:04 2015-02-01"', '$.datetime("HH24:MI&nbsp;YYYY-MM-DD")' RETURNING date)</literal>
19024 <returnvalue>2015-02-01</returnvalue>
19025 </para>
19026 <para>
19027 <literal>JSON_VALUE(jsonb '[1,2]', 'strict $[$off]' PASSING 1 as off)</literal>
19028 <returnvalue>2</returnvalue>
19029 </para>
19030 <para>
19031 <literal>JSON_VALUE(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR)</literal>
19032 <returnvalue>9</returnvalue>
19033 </para>
19034 </entry>
19035 </row>
19036 </tbody>
19037 </tgroup>
19038 </table>
19039 <note>
19040 <para>
19041 The <replaceable>context_item</replaceable> expression is converted to
19042 <type>jsonb</type> by an implicit cast if the expression is not already of
19043 type <type>jsonb</type>. Note, however, that any parsing errors that occur
19044 during that conversion are thrown unconditionally, that is, are not
19045 handled according to the (specified or implicit) <literal>ON ERROR</literal>
19046 clause.
19047 </para>
19048 </note>
19049 <note>
19050 <para>
19051 <function>JSON_VALUE()</function> returns an SQL NULL if
19052 <replaceable>path_expression</replaceable> returns a JSON
19053 <literal>null</literal>, whereas <function>JSON_QUERY()</function> returns
19054 the JSON <literal>null</literal> as is.
19055 </para>
19056 </note>
19057 </sect2>
19059 <sect2 id="functions-sqljson-table">
19060 <title>JSON_TABLE</title>
19061 <indexterm>
19062 <primary>json_table</primary>
19063 </indexterm>
19065 <para>
19066 <function>JSON_TABLE</function> is an SQL/JSON function which
19067 queries <acronym>JSON</acronym> data
19068 and presents the results as a relational view, which can be accessed as a
19069 regular SQL table. You can use <function>JSON_TABLE</function> inside
19070 the <literal>FROM</literal> clause of a <literal>SELECT</literal>,
19071 <literal>UPDATE</literal>, or <literal>DELETE</literal> and as data source
19072 in a <literal>MERGE</literal> statement.
19073 </para>
19075 <para>
19076 Taking JSON data as input, <function>JSON_TABLE</function> uses a JSON path
19077 expression to extract a part of the provided data to use as a
19078 <firstterm>row pattern</firstterm> for the constructed view. Each SQL/JSON
19079 value given by the row pattern serves as source for a separate row in the
19080 constructed view.
19081 </para>
19083 <para>
19084 To split the row pattern into columns, <function>JSON_TABLE</function>
19085 provides the <literal>COLUMNS</literal> clause that defines the
19086 schema of the created view. For each column, a separate JSON path expression
19087 can be specified to be evaluated against the row pattern to get an SQL/JSON
19088 value that will become the value for the specified column in a given output
19089 row.
19090 </para>
19092 <para>
19093 JSON data stored at a nested level of the row pattern can be extracted using
19094 the <literal>NESTED PATH</literal> clause. Each
19095 <literal>NESTED PATH</literal> clause can be used to generate one or more
19096 columns using the data from a nested level of the row pattern. Those
19097 columns can be specified using a <literal>COLUMNS</literal> clause that
19098 looks similar to the top-level COLUMNS clause. Rows constructed from
19099 NESTED COLUMNS are called <firstterm>child rows</firstterm> and are joined
19100 against the row constructed from the columns specified in the parent
19101 <literal>COLUMNS</literal> clause to get the row in the final view. Child
19102 columns themselves may contain a <literal>NESTED PATH</literal>
19103 specification thus allowing to extract data located at arbitrary nesting
19104 levels. Columns produced by multiple <literal>NESTED PATH</literal>s at the
19105 same level are considered to be <firstterm>siblings</firstterm> of each
19106 other and their rows after joining with the parent row are combined using
19107 UNION.
19108 </para>
19110 <para>
19111 The rows produced by <function>JSON_TABLE</function> are laterally
19112 joined to the row that generated them, so you do not have to explicitly join
19113 the constructed view with the original table holding <acronym>JSON</acronym>
19114 data.
19115 </para>
19117 <para>
19118 The syntax is:
19119 </para>
19121 <synopsis>
19122 JSON_TABLE (
19123 <replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> <optional> PASSING { <replaceable>value</replaceable> AS <replaceable>varname</replaceable> } <optional>, ...</optional> </optional>
19124 COLUMNS ( <replaceable class="parameter">json_table_column</replaceable> <optional>, ...</optional> )
19125 <optional> { <literal>ERROR</literal> | <literal>EMPTY</literal> <optional>ARRAY</optional>} <literal>ON ERROR</literal> </optional>
19128 <phrase>
19129 where <replaceable class="parameter">json_table_column</replaceable> is:
19130 </phrase>
19131 <replaceable>name</replaceable> FOR ORDINALITY
19132 | <replaceable>name</replaceable> <replaceable>type</replaceable>
19133 <optional> FORMAT JSON <optional>ENCODING <literal>UTF8</literal></optional></optional>
19134 <optional> PATH <replaceable>path_expression</replaceable> </optional>
19135 <optional> { WITHOUT | WITH { CONDITIONAL | <optional>UNCONDITIONAL</optional> } } <optional> ARRAY </optional> WRAPPER </optional>
19136 <optional> { KEEP | OMIT } QUOTES <optional> ON SCALAR STRING </optional> </optional>
19137 <optional> { ERROR | NULL | EMPTY { <optional>ARRAY</optional> | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON EMPTY </optional>
19138 <optional> { ERROR | NULL | EMPTY { <optional>ARRAY</optional> | OBJECT } | DEFAULT <replaceable>expression</replaceable> } ON ERROR </optional>
19139 | <replaceable>name</replaceable> <replaceable>type</replaceable> EXISTS <optional> PATH <replaceable>path_expression</replaceable> </optional>
19140 <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR </optional>
19141 | NESTED <optional> PATH </optional> <replaceable>path_expression</replaceable> <optional> AS <replaceable>json_path_name</replaceable> </optional> COLUMNS ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
19142 </synopsis>
19144 <para>
19145 Each syntax element is described below in more detail.
19146 </para>
19148 <variablelist>
19149 <varlistentry>
19150 <term>
19151 <literal><replaceable>context_item</replaceable>, <replaceable>path_expression</replaceable> <optional> <literal>AS</literal> <replaceable>json_path_name</replaceable> </optional> <optional> <literal>PASSING</literal> { <replaceable>value</replaceable> <literal>AS</literal> <replaceable>varname</replaceable> } <optional>, ...</optional></optional></literal>
19152 </term>
19153 <listitem>
19154 <para>
19155 The <replaceable>context_item</replaceable> specifies the input document
19156 to query, the <replaceable>path_expression</replaceable> is an SQL/JSON
19157 path expression defining the query, and <replaceable>json_path_name</replaceable>
19158 is an optional name for the <replaceable>path_expression</replaceable>.
19159 The optional <literal>PASSING</literal> clause provides data values for
19160 the variables mentioned in the <replaceable>path_expression</replaceable>.
19161 The result of the input data evaluation using the aforementioned elements
19162 is called the <firstterm>row pattern</firstterm>, which is used as the
19163 source for row values in the constructed view.
19164 </para>
19165 </listitem>
19166 </varlistentry>
19168 <varlistentry>
19169 <term>
19170 <literal>COLUMNS</literal> ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
19171 </term>
19172 <listitem>
19174 <para>
19175 The <literal>COLUMNS</literal> clause defining the schema of the
19176 constructed view. In this clause, you can specify each column to be
19177 filled with an SQL/JSON value obtained by applying a JSON path expression
19178 against the row pattern. <replaceable>json_table_column</replaceable> has
19179 the following variants:
19180 </para>
19182 <variablelist>
19183 <varlistentry>
19184 <term>
19185 <replaceable>name</replaceable> <literal>FOR ORDINALITY</literal>
19186 </term>
19187 <listitem>
19188 <para>
19189 Adds an ordinality column that provides sequential row numbering starting
19190 from 1. Each <literal>NESTED PATH</literal> (see below) gets its own
19191 counter for any nested ordinality columns.
19192 </para>
19193 </listitem>
19194 </varlistentry>
19196 <varlistentry>
19197 <term>
19198 <literal><replaceable>name</replaceable> <replaceable>type</replaceable>
19199 <optional><literal>FORMAT JSON</literal> <optional>ENCODING <literal>UTF8</literal></optional></optional>
19200 <optional> <literal>PATH</literal> <replaceable>path_expression</replaceable> </optional></literal>
19201 </term>
19202 <listitem>
19203 <para>
19204 Inserts an SQL/JSON value obtained by applying
19205 <replaceable>path_expression</replaceable> against the row pattern into
19206 the view's output row after coercing it to specified
19207 <replaceable>type</replaceable>.
19208 </para>
19209 <para>
19210 Specifying <literal>FORMAT JSON</literal> makes it explicit that you
19211 expect the value to be a valid <type>json</type> object. It only
19212 makes sense to specify <literal>FORMAT JSON</literal> if
19213 <replaceable>type</replaceable> is one of <type>bpchar</type>,
19214 <type>bytea</type>, <type>character varying</type>, <type>name</type>,
19215 <type>json</type>, <type>jsonb</type>, <type>text</type>, or a domain over
19216 these types.
19217 </para>
19218 <para>
19219 Optionally, you can specify <literal>WRAPPER</literal> and
19220 <literal>QUOTES</literal> clauses to format the output. Note that
19221 specifying <literal>OMIT QUOTES</literal> overrides
19222 <literal>FORMAT JSON</literal> if also specified, because unquoted
19223 literals do not constitute valid <type>json</type> values.
19224 </para>
19225 <para>
19226 Optionally, you can use <literal>ON EMPTY</literal> and
19227 <literal>ON ERROR</literal> clauses to specify whether to throw the error
19228 or return the specified value when the result of JSON path evaluation is
19229 empty and when an error occurs during JSON path evaluation or when
19230 coercing the SQL/JSON value to the specified type, respectively. The
19231 default for both is to return a <literal>NULL</literal> value.
19232 </para>
19233 <note>
19234 <para>
19235 This clause is internally turned into and has the same semantics as
19236 <function>JSON_VALUE</function> or <function>JSON_QUERY</function>.
19237 The latter if the specified type is not a scalar type or if either of
19238 <literal>FORMAT JSON</literal>, <literal>WRAPPER</literal>, or
19239 <literal>QUOTES</literal> clause is present.
19240 </para>
19241 </note>
19242 </listitem>
19243 </varlistentry>
19245 <varlistentry>
19246 <term>
19247 <replaceable>name</replaceable> <replaceable>type</replaceable>
19248 <literal>EXISTS</literal> <optional> <literal>PATH</literal> <replaceable>path_expression</replaceable> </optional>
19249 </term>
19250 <listitem>
19251 <para>
19252 Inserts a boolean value obtained by applying
19253 <replaceable>path_expression</replaceable> against the row pattern
19254 into the view's output row after coercing it to specified
19255 <replaceable>type</replaceable>.
19256 </para>
19257 <para>
19258 The value corresponds to whether applying the <literal>PATH</literal>
19259 expression to the row pattern yields any values.
19260 </para>
19261 <para>
19262 The specified <replaceable>type</replaceable> should have a cast from the
19263 <type>boolean</type> type.
19264 </para>
19265 <para>
19266 Optionally, you can use <literal>ON ERROR</literal> to specify whether to
19267 throw the error or return the specified value when an error occurs during
19268 JSON path evaluation or when coercing SQL/JSON value to the specified
19269 type. The default is to return a boolean value
19270 <literal>FALSE</literal>.
19271 </para>
19272 <note>
19273 <para>
19274 This clause is internally turned into and has the same semantics as
19275 <function>JSON_EXISTS</function>.
19276 </para>
19277 </note>
19278 </listitem>
19279 </varlistentry>
19281 <varlistentry>
19282 <term>
19283 <literal>NESTED <optional> PATH </optional></literal> <replaceable>path_expression</replaceable> <optional> <literal>AS</literal> <replaceable>json_path_name</replaceable> </optional>
19284 <literal>COLUMNS</literal> ( <replaceable>json_table_column</replaceable> <optional>, ...</optional> )
19285 </term>
19286 <listitem>
19288 <para>
19289 Extracts SQL/JSON values from nested levels of the row pattern,
19290 generates one or more columns as defined by the <literal>COLUMNS</literal>
19291 subclause, and inserts the extracted SQL/JSON values into those
19292 columns. The <replaceable>json_table_column</replaceable>
19293 expression in the <literal>COLUMNS</literal> subclause uses the same
19294 syntax as in the parent <literal>COLUMNS</literal> clause.
19295 </para>
19297 <para>
19298 The <literal>NESTED PATH</literal> syntax is recursive,
19299 so you can go down multiple nested levels by specifying several
19300 <literal>NESTED PATH</literal> subclauses within each other.
19301 It allows to unnest the hierarchy of JSON objects and arrays
19302 in a single function invocation rather than chaining several
19303 <function>JSON_TABLE</function> expressions in an SQL statement.
19304 </para>
19305 </listitem>
19306 </varlistentry>
19307 </variablelist>
19309 <note>
19310 <para>
19311 In each variant of <replaceable>json_table_column</replaceable> described
19312 above, if the <literal>PATH</literal> clause is omitted, path expression
19313 <literal>$.<replaceable>name</replaceable></literal> is used, where
19314 <replaceable>name</replaceable> is the provided column name.
19315 </para>
19316 </note>
19318 </listitem>
19319 </varlistentry>
19321 <varlistentry>
19322 <term>
19323 <literal>AS</literal> <replaceable>json_path_name</replaceable>
19324 </term>
19325 <listitem>
19327 <para>
19328 The optional <replaceable>json_path_name</replaceable> serves as an
19329 identifier of the provided <replaceable>path_expression</replaceable>.
19330 The name must be unique and distinct from the column names.
19331 </para>
19332 </listitem>
19333 </varlistentry>
19335 <varlistentry>
19336 <term>
19337 { <literal>ERROR</literal> | <literal>EMPTY</literal> } <literal>ON ERROR</literal>
19338 </term>
19339 <listitem>
19341 <para>
19342 The optional <literal>ON ERROR</literal> can be used to specify how to
19343 handle errors when evaluating the top-level
19344 <replaceable>path_expression</replaceable>. Use <literal>ERROR</literal>
19345 if you want the errors to be thrown and <literal>EMPTY</literal> to
19346 return an empty table, that is, a table containing 0 rows. Note that
19347 this clause does not affect the errors that occur when evaluating
19348 columns, for which the behavior depends on whether the
19349 <literal>ON ERROR</literal> clause is specified against a given column.
19350 </para>
19351 </listitem>
19352 </varlistentry>
19353 </variablelist>
19355 <para>Examples</para>
19357 <para>
19358 In the examples that follow, the following table containing JSON data
19359 will be used:
19361 <programlisting>
19362 CREATE TABLE my_films ( js jsonb );
19364 INSERT INTO my_films VALUES (
19365 '{ "favorites" : [
19366 { "kind" : "comedy", "films" : [
19367 { "title" : "Bananas",
19368 "director" : "Woody Allen"},
19369 { "title" : "The Dinner Game",
19370 "director" : "Francis Veber" } ] },
19371 { "kind" : "horror", "films" : [
19372 { "title" : "Psycho",
19373 "director" : "Alfred Hitchcock" } ] },
19374 { "kind" : "thriller", "films" : [
19375 { "title" : "Vertigo",
19376 "director" : "Alfred Hitchcock" } ] },
19377 { "kind" : "drama", "films" : [
19378 { "title" : "Yojimbo",
19379 "director" : "Akira Kurosawa" } ] }
19380 ] }');
19381 </programlisting>
19383 </para>
19384 <para>
19385 The following query shows how to use <function>JSON_TABLE</function> to
19386 turn the JSON objects in the <structname>my_films</structname> table
19387 to a view containing columns for the keys <literal>kind</literal>,
19388 <literal>title</literal>, and <literal>director</literal> contained in
19389 the original JSON along with an ordinality column:
19391 <programlisting>
19392 SELECT jt.* FROM
19393 my_films,
19394 JSON_TABLE (js, '$.favorites[*]' COLUMNS (
19395 id FOR ORDINALITY,
19396 kind text PATH '$.kind',
19397 title text PATH '$.films[*].title' WITH WRAPPER,
19398 director text PATH '$.films[*].director' WITH WRAPPER)) AS jt;
19399 </programlisting>
19401 <screen>
19402 id | kind | title | director
19403 ----+----------+--------------------------------+----------------------------------
19404 1 | comedy | ["Bananas", "The Dinner Game"] | ["Woody Allen", "Francis Veber"]
19405 2 | horror | ["Psycho"] | ["Alfred Hitchcock"]
19406 3 | thriller | ["Vertigo"] | ["Alfred Hitchcock"]
19407 4 | drama | ["Yojimbo"] | ["Akira Kurosawa"]
19408 (4 rows)
19409 </screen>
19411 </para>
19412 <para>
19413 The following is a modified version of the above query to show the
19414 usage of <literal>PASSING</literal> arguments in the filter specified in
19415 the top-level JSON path expression and the various options for the
19416 individual columns:
19418 <programlisting>
19419 SELECT jt.* FROM
19420 my_films,
19421 JSON_TABLE (js, '$.favorites[*] ? (@.films[*].director == $filter)'
19422 PASSING 'Alfred Hitchcock' AS filter, 'Vertigo' AS filter2
19423 COLUMNS (
19424 id FOR ORDINALITY,
19425 kind text PATH '$.kind',
19426 title text FORMAT JSON PATH '$.films[*].title' OMIT QUOTES,
19427 director text PATH '$.films[*].director' KEEP QUOTES)) AS jt;
19428 </programlisting>
19430 <screen>
19431 id | kind | title | director
19432 ----+----------+---------+--------------------
19433 1 | horror | Psycho | "Alfred Hitchcock"
19434 2 | thriller | Vertigo | "Alfred Hitchcock"
19435 (2 rows)
19436 </screen>
19438 </para>
19439 <para>
19440 The following is a modified version of the above query to show the usage
19441 of <literal>NESTED PATH</literal> for populating title and director
19442 columns, illustrating how they are joined to the parent columns id and
19443 kind:
19445 <programlisting>
19446 SELECT jt.* FROM
19447 my_films,
19448 JSON_TABLE ( js, '$.favorites[*] ? (@.films[*].director == $filter)'
19449 PASSING 'Alfred Hitchcock' AS filter
19450 COLUMNS (
19451 id FOR ORDINALITY,
19452 kind text PATH '$.kind',
19453 NESTED PATH '$.films[*]' COLUMNS (
19454 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
19455 director text PATH '$.director' KEEP QUOTES))) AS jt;
19456 </programlisting>
19458 <screen>
19459 id | kind | title | director
19460 ----+----------+---------+--------------------
19461 1 | horror | Psycho | "Alfred Hitchcock"
19462 2 | thriller | Vertigo | "Alfred Hitchcock"
19463 (2 rows)
19464 </screen>
19466 </para>
19468 <para>
19469 The following is the same query but without the filter in the root
19470 path:
19472 <programlisting>
19473 SELECT jt.* FROM
19474 my_films,
19475 JSON_TABLE ( js, '$.favorites[*]'
19476 COLUMNS (
19477 id FOR ORDINALITY,
19478 kind text PATH '$.kind',
19479 NESTED PATH '$.films[*]' COLUMNS (
19480 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
19481 director text PATH '$.director' KEEP QUOTES))) AS jt;
19482 </programlisting>
19484 <screen>
19485 id | kind | title | director
19486 ----+----------+-----------------+--------------------
19487 1 | comedy | Bananas | "Woody Allen"
19488 1 | comedy | The Dinner Game | "Francis Veber"
19489 2 | horror | Psycho | "Alfred Hitchcock"
19490 3 | thriller | Vertigo | "Alfred Hitchcock"
19491 4 | drama | Yojimbo | "Akira Kurosawa"
19492 (5 rows)
19493 </screen>
19495 </para>
19497 <para>
19498 The following shows another query using a different <type>JSON</type>
19499 object as input. It shows the UNION "sibling join" between
19500 <literal>NESTED</literal> paths <literal>$.movies[*]</literal> and
19501 <literal>$.books[*]</literal> and also the usage of
19502 <literal>FOR ORDINALITY</literal> column at <literal>NESTED</literal>
19503 levels (columns <literal>movie_id</literal>, <literal>book_id</literal>,
19504 and <literal>author_id</literal>):
19506 <programlisting>
19507 SELECT * FROM JSON_TABLE (
19508 '{"favorites":
19509 {"movies":
19510 [{"name": "One", "director": "John Doe"},
19511 {"name": "Two", "director": "Don Joe"}],
19512 "books":
19513 [{"name": "Mystery", "authors": [{"name": "Brown Dan"}]},
19514 {"name": "Wonder", "authors": [{"name": "Jun Murakami"}, {"name":"Craig Doe"}]}]
19515 }}'::json, '$.favorites[*]'
19516 COLUMNS (
19517 user_id FOR ORDINALITY,
19518 NESTED '$.movies[*]'
19519 COLUMNS (
19520 movie_id FOR ORDINALITY,
19521 mname text PATH '$.name',
19522 director text),
19523 NESTED '$.books[*]'
19524 COLUMNS (
19525 book_id FOR ORDINALITY,
19526 bname text PATH '$.name',
19527 NESTED '$.authors[*]'
19528 COLUMNS (
19529 author_id FOR ORDINALITY,
19530 author_name text PATH '$.name'))));
19531 </programlisting>
19533 <screen>
19534 user_id | movie_id | mname | director | book_id | bname | author_id | author_name
19535 ---------+----------+-------+----------+---------+---------+-----------+--------------
19536 1 | 1 | One | John Doe | | | |
19537 1 | 2 | Two | Don Joe | | | |
19538 1 | | | | 1 | Mystery | 1 | Brown Dan
19539 1 | | | | 2 | Wonder | 1 | Jun Murakami
19540 1 | | | | 2 | Wonder | 2 | Craig Doe
19541 (5 rows)
19542 </screen>
19544 </para>
19545 </sect2>
19546 </sect1>
19548 <sect1 id="functions-sequence">
19549 <title>Sequence Manipulation Functions</title>
19551 <indexterm>
19552 <primary>sequence</primary>
19553 </indexterm>
19555 <para>
19556 This section describes functions for operating on <firstterm>sequence
19557 objects</firstterm>, also called sequence generators or just sequences.
19558 Sequence objects are special single-row tables created with <xref
19559 linkend="sql-createsequence"/>.
19560 Sequence objects are commonly used to generate unique identifiers
19561 for rows of a table. The sequence functions, listed in <xref
19562 linkend="functions-sequence-table"/>, provide simple, multiuser-safe
19563 methods for obtaining successive sequence values from sequence
19564 objects.
19565 </para>
19567 <table id="functions-sequence-table">
19568 <title>Sequence Functions</title>
19569 <tgroup cols="1">
19570 <thead>
19571 <row>
19572 <entry role="func_table_entry"><para role="func_signature">
19573 Function
19574 </para>
19575 <para>
19576 Description
19577 </para></entry>
19578 </row>
19579 </thead>
19581 <tbody>
19582 <row>
19583 <entry role="func_table_entry"><para role="func_signature">
19584 <indexterm>
19585 <primary>nextval</primary>
19586 </indexterm>
19587 <function>nextval</function> ( <type>regclass</type> )
19588 <returnvalue>bigint</returnvalue>
19589 </para>
19590 <para>
19591 Advances the sequence object to its next value and returns that value.
19592 This is done atomically: even if multiple sessions
19593 execute <function>nextval</function> concurrently, each will safely
19594 receive a distinct sequence value.
19595 If the sequence object has been created with default parameters,
19596 successive <function>nextval</function> calls will return successive
19597 values beginning with 1. Other behaviors can be obtained by using
19598 appropriate parameters in the <xref linkend="sql-createsequence"/>
19599 command.
19600 </para>
19601 <para>
19602 This function requires <literal>USAGE</literal>
19603 or <literal>UPDATE</literal> privilege on the sequence.
19604 </para></entry>
19605 </row>
19607 <row>
19608 <entry role="func_table_entry"><para role="func_signature">
19609 <indexterm>
19610 <primary>setval</primary>
19611 </indexterm>
19612 <function>setval</function> ( <type>regclass</type>, <type>bigint</type> <optional>, <type>boolean</type> </optional> )
19613 <returnvalue>bigint</returnvalue>
19614 </para>
19615 <para>
19616 Sets the sequence object's current value, and optionally
19617 its <literal>is_called</literal> flag. The two-parameter
19618 form sets the sequence's <literal>last_value</literal> field to the
19619 specified value and sets its <literal>is_called</literal> field to
19620 <literal>true</literal>, meaning that the next
19621 <function>nextval</function> will advance the sequence before
19622 returning a value. The value that will be reported
19623 by <function>currval</function> is also set to the specified value.
19624 In the three-parameter form, <literal>is_called</literal> can be set
19625 to either <literal>true</literal>
19626 or <literal>false</literal>. <literal>true</literal> has the same
19627 effect as the two-parameter form. If it is set
19628 to <literal>false</literal>, the next <function>nextval</function>
19629 will return exactly the specified value, and sequence advancement
19630 commences with the following <function>nextval</function>.
19631 Furthermore, the value reported by <function>currval</function> is not
19632 changed in this case. For example,
19633 <programlisting>
19634 SELECT setval('myseq', 42); <lineannotation>Next <function>nextval</function> will return 43</lineannotation>
19635 SELECT setval('myseq', 42, true); <lineannotation>Same as above</lineannotation>
19636 SELECT setval('myseq', 42, false); <lineannotation>Next <function>nextval</function> will return 42</lineannotation>
19637 </programlisting>
19638 The result returned by <function>setval</function> is just the value of its
19639 second argument.
19640 </para>
19641 <para>
19642 This function requires <literal>UPDATE</literal> privilege on the
19643 sequence.
19644 </para></entry>
19645 </row>
19647 <row>
19648 <entry role="func_table_entry"><para role="func_signature">
19649 <indexterm>
19650 <primary>currval</primary>
19651 </indexterm>
19652 <function>currval</function> ( <type>regclass</type> )
19653 <returnvalue>bigint</returnvalue>
19654 </para>
19655 <para>
19656 Returns the value most recently obtained
19657 by <function>nextval</function> for this sequence in the current
19658 session. (An error is reported if <function>nextval</function> has
19659 never been called for this sequence in this session.) Because this is
19660 returning a session-local value, it gives a predictable answer whether
19661 or not other sessions have executed <function>nextval</function> since
19662 the current session did.
19663 </para>
19664 <para>
19665 This function requires <literal>USAGE</literal>
19666 or <literal>SELECT</literal> privilege on the sequence.
19667 </para></entry>
19668 </row>
19670 <row>
19671 <entry role="func_table_entry"><para role="func_signature">
19672 <indexterm>
19673 <primary>lastval</primary>
19674 </indexterm>
19675 <function>lastval</function> ()
19676 <returnvalue>bigint</returnvalue>
19677 </para>
19678 <para>
19679 Returns the value most recently returned by
19680 <function>nextval</function> in the current session. This function is
19681 identical to <function>currval</function>, except that instead
19682 of taking the sequence name as an argument it refers to whichever
19683 sequence <function>nextval</function> was most recently applied to
19684 in the current session. It is an error to call
19685 <function>lastval</function> if <function>nextval</function>
19686 has not yet been called in the current session.
19687 </para>
19688 <para>
19689 This function requires <literal>USAGE</literal>
19690 or <literal>SELECT</literal> privilege on the last used sequence.
19691 </para></entry>
19692 </row>
19693 </tbody>
19694 </tgroup>
19695 </table>
19697 <caution>
19698 <para>
19699 To avoid blocking concurrent transactions that obtain numbers from
19700 the same sequence, the value obtained by <function>nextval</function>
19701 is not reclaimed for re-use if the calling transaction later aborts.
19702 This means that transaction aborts or database crashes can result in
19703 gaps in the sequence of assigned values. That can happen without a
19704 transaction abort, too. For example an <command>INSERT</command> with
19705 an <literal>ON CONFLICT</literal> clause will compute the to-be-inserted
19706 tuple, including doing any required <function>nextval</function>
19707 calls, before detecting any conflict that would cause it to follow
19708 the <literal>ON CONFLICT</literal> rule instead.
19709 Thus, <productname>PostgreSQL</productname> sequence
19710 objects <emphasis>cannot be used to obtain <quote>gapless</quote>
19711 sequences</emphasis>.
19712 </para>
19714 <para>
19715 Likewise, sequence state changes made by <function>setval</function>
19716 are immediately visible to other transactions, and are not undone if
19717 the calling transaction rolls back.
19718 </para>
19720 <para>
19721 If the database cluster crashes before committing a transaction
19722 containing a <function>nextval</function>
19723 or <function>setval</function> call, the sequence state change might
19724 not have made its way to persistent storage, so that it is uncertain
19725 whether the sequence will have its original or updated state after the
19726 cluster restarts. This is harmless for usage of the sequence within
19727 the database, since other effects of uncommitted transactions will not
19728 be visible either. However, if you wish to use a sequence value for
19729 persistent outside-the-database purposes, make sure that the
19730 <function>nextval</function> call has been committed before doing so.
19731 </para>
19732 </caution>
19734 <para>
19735 The sequence to be operated on by a sequence function is specified by
19736 a <type>regclass</type> argument, which is simply the OID of the sequence in the
19737 <structname>pg_class</structname> system catalog. You do not have to look up the
19738 OID by hand, however, since the <type>regclass</type> data type's input
19739 converter will do the work for you. See <xref linkend="datatype-oid"/>
19740 for details.
19741 </para>
19742 </sect1>
19745 <sect1 id="functions-conditional">
19746 <title>Conditional Expressions</title>
19748 <indexterm>
19749 <primary>CASE</primary>
19750 </indexterm>
19752 <indexterm>
19753 <primary>conditional expression</primary>
19754 </indexterm>
19756 <para>
19757 This section describes the <acronym>SQL</acronym>-compliant conditional expressions
19758 available in <productname>PostgreSQL</productname>.
19759 </para>
19761 <tip>
19762 <para>
19763 If your needs go beyond the capabilities of these conditional
19764 expressions, you might want to consider writing a server-side function
19765 in a more expressive programming language.
19766 </para>
19767 </tip>
19769 <note>
19770 <para>
19771 Although <token>COALESCE</token>, <token>GREATEST</token>, and
19772 <token>LEAST</token> are syntactically similar to functions, they are
19773 not ordinary functions, and thus cannot be used with explicit
19774 <token>VARIADIC</token> array arguments.
19775 </para>
19776 </note>
19778 <sect2 id="functions-case">
19779 <title><literal>CASE</literal></title>
19781 <para>
19782 The <acronym>SQL</acronym> <token>CASE</token> expression is a
19783 generic conditional expression, similar to if/else statements in
19784 other programming languages:
19786 <synopsis>
19787 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
19788 <optional>WHEN ...</optional>
19789 <optional>ELSE <replaceable>result</replaceable></optional>
19791 </synopsis>
19793 <token>CASE</token> clauses can be used wherever
19794 an expression is valid. Each <replaceable>condition</replaceable> is an
19795 expression that returns a <type>boolean</type> result. If the condition's
19796 result is true, the value of the <token>CASE</token> expression is the
19797 <replaceable>result</replaceable> that follows the condition, and the
19798 remainder of the <token>CASE</token> expression is not processed. If the
19799 condition's result is not true, any subsequent <token>WHEN</token> clauses
19800 are examined in the same manner. If no <token>WHEN</token>
19801 <replaceable>condition</replaceable> yields true, the value of the
19802 <token>CASE</token> expression is the <replaceable>result</replaceable> of the
19803 <token>ELSE</token> clause. If the <token>ELSE</token> clause is
19804 omitted and no condition is true, the result is null.
19805 </para>
19807 <para>
19808 An example:
19809 <screen>
19810 SELECT * FROM test;
19819 SELECT a,
19820 CASE WHEN a=1 THEN 'one'
19821 WHEN a=2 THEN 'two'
19822 ELSE 'other'
19824 FROM test;
19826 a | case
19827 ---+-------
19828 1 | one
19829 2 | two
19830 3 | other
19831 </screen>
19832 </para>
19834 <para>
19835 The data types of all the <replaceable>result</replaceable>
19836 expressions must be convertible to a single output type.
19837 See <xref linkend="typeconv-union-case"/> for more details.
19838 </para>
19840 <para>
19841 There is a <quote>simple</quote> form of <token>CASE</token> expression
19842 that is a variant of the general form above:
19844 <synopsis>
19845 CASE <replaceable>expression</replaceable>
19846 WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
19847 <optional>WHEN ...</optional>
19848 <optional>ELSE <replaceable>result</replaceable></optional>
19850 </synopsis>
19852 The first
19853 <replaceable>expression</replaceable> is computed, then compared to
19854 each of the <replaceable>value</replaceable> expressions in the
19855 <token>WHEN</token> clauses until one is found that is equal to it. If
19856 no match is found, the <replaceable>result</replaceable> of the
19857 <token>ELSE</token> clause (or a null value) is returned. This is similar
19858 to the <function>switch</function> statement in C.
19859 </para>
19861 <para>
19862 The example above can be written using the simple
19863 <token>CASE</token> syntax:
19864 <screen>
19865 SELECT a,
19866 CASE a WHEN 1 THEN 'one'
19867 WHEN 2 THEN 'two'
19868 ELSE 'other'
19870 FROM test;
19872 a | case
19873 ---+-------
19874 1 | one
19875 2 | two
19876 3 | other
19877 </screen>
19878 </para>
19880 <para>
19881 A <token>CASE</token> expression does not evaluate any subexpressions
19882 that are not needed to determine the result. For example, this is a
19883 possible way of avoiding a division-by-zero failure:
19884 <programlisting>
19885 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
19886 </programlisting>
19887 </para>
19889 <note>
19890 <para>
19891 As described in <xref linkend="syntax-express-eval"/>, there are various
19892 situations in which subexpressions of an expression are evaluated at
19893 different times, so that the principle that <quote><token>CASE</token>
19894 evaluates only necessary subexpressions</quote> is not ironclad. For
19895 example a constant <literal>1/0</literal> subexpression will usually result in
19896 a division-by-zero failure at planning time, even if it's within
19897 a <token>CASE</token> arm that would never be entered at run time.
19898 </para>
19899 </note>
19900 </sect2>
19902 <sect2 id="functions-coalesce-nvl-ifnull">
19903 <title><literal>COALESCE</literal></title>
19905 <indexterm>
19906 <primary>COALESCE</primary>
19907 </indexterm>
19909 <indexterm>
19910 <primary>NVL</primary>
19911 </indexterm>
19913 <indexterm>
19914 <primary>IFNULL</primary>
19915 </indexterm>
19917 <synopsis>
19918 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
19919 </synopsis>
19921 <para>
19922 The <function>COALESCE</function> function returns the first of its
19923 arguments that is not null. Null is returned only if all arguments
19924 are null. It is often used to substitute a default value for
19925 null values when data is retrieved for display, for example:
19926 <programlisting>
19927 SELECT COALESCE(description, short_description, '(none)') ...
19928 </programlisting>
19929 This returns <varname>description</varname> if it is not null, otherwise
19930 <varname>short_description</varname> if it is not null, otherwise <literal>(none)</literal>.
19931 </para>
19933 <para>
19934 The arguments must all be convertible to a common data type, which
19935 will be the type of the result (see
19936 <xref linkend="typeconv-union-case"/> for details).
19937 </para>
19939 <para>
19940 Like a <token>CASE</token> expression, <function>COALESCE</function> only
19941 evaluates the arguments that are needed to determine the result;
19942 that is, arguments to the right of the first non-null argument are
19943 not evaluated. This SQL-standard function provides capabilities similar
19944 to <function>NVL</function> and <function>IFNULL</function>, which are used in some other
19945 database systems.
19946 </para>
19947 </sect2>
19949 <sect2 id="functions-nullif">
19950 <title><literal>NULLIF</literal></title>
19952 <indexterm>
19953 <primary>NULLIF</primary>
19954 </indexterm>
19956 <synopsis>
19957 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
19958 </synopsis>
19960 <para>
19961 The <function>NULLIF</function> function returns a null value if
19962 <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
19963 otherwise it returns <replaceable>value1</replaceable>.
19964 This can be used to perform the inverse operation of the
19965 <function>COALESCE</function> example given above:
19966 <programlisting>
19967 SELECT NULLIF(value, '(none)') ...
19968 </programlisting>
19969 In this example, if <literal>value</literal> is <literal>(none)</literal>,
19970 null is returned, otherwise the value of <literal>value</literal>
19971 is returned.
19972 </para>
19974 <para>
19975 The two arguments must be of comparable types.
19976 To be specific, they are compared exactly as if you had
19977 written <literal><replaceable>value1</replaceable>
19978 = <replaceable>value2</replaceable></literal>, so there must be a
19979 suitable <literal>=</literal> operator available.
19980 </para>
19982 <para>
19983 The result has the same type as the first argument &mdash; but there is
19984 a subtlety. What is actually returned is the first argument of the
19985 implied <literal>=</literal> operator, and in some cases that will have
19986 been promoted to match the second argument's type. For
19987 example, <literal>NULLIF(1, 2.2)</literal> yields <type>numeric</type>,
19988 because there is no <type>integer</type> <literal>=</literal>
19989 <type>numeric</type> operator,
19990 only <type>numeric</type> <literal>=</literal> <type>numeric</type>.
19991 </para>
19993 </sect2>
19995 <sect2 id="functions-greatest-least">
19996 <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
19998 <indexterm>
19999 <primary>GREATEST</primary>
20000 </indexterm>
20001 <indexterm>
20002 <primary>LEAST</primary>
20003 </indexterm>
20005 <synopsis>
20006 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
20007 </synopsis>
20008 <synopsis>
20009 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
20010 </synopsis>
20012 <para>
20013 The <function>GREATEST</function> and <function>LEAST</function> functions select the
20014 largest or smallest value from a list of any number of expressions.
20015 The expressions must all be convertible to a common data type, which
20016 will be the type of the result
20017 (see <xref linkend="typeconv-union-case"/> for details).
20018 </para>
20020 <para>
20021 NULL values in the argument list are ignored. The result will be NULL
20022 only if all the expressions evaluate to NULL. (This is a deviation from
20023 the SQL standard. According to the standard, the return value is NULL if
20024 any argument is NULL. Some other databases behave this way.)
20025 </para>
20026 </sect2>
20027 </sect1>
20029 <sect1 id="functions-array">
20030 <title>Array Functions and Operators</title>
20032 <para>
20033 <xref linkend="array-operators-table"/> shows the specialized operators
20034 available for array types.
20035 In addition to those, the usual comparison operators shown in <xref
20036 linkend="functions-comparison-op-table"/> are available for
20037 arrays. The comparison operators compare the array contents
20038 element-by-element, using the default B-tree comparison function for
20039 the element data type, and sort based on the first difference.
20040 In multidimensional arrays the elements are visited in row-major order
20041 (last subscript varies most rapidly).
20042 If the contents of two arrays are equal but the dimensionality is
20043 different, the first difference in the dimensionality information
20044 determines the sort order.
20045 </para>
20047 <table id="array-operators-table">
20048 <title>Array Operators</title>
20049 <tgroup cols="1">
20050 <thead>
20051 <row>
20052 <entry role="func_table_entry"><para role="func_signature">
20053 Operator
20054 </para>
20055 <para>
20056 Description
20057 </para>
20058 <para>
20059 Example(s)
20060 </para></entry>
20061 </row>
20062 </thead>
20064 <tbody>
20065 <row>
20066 <entry role="func_table_entry"><para role="func_signature">
20067 <type>anyarray</type> <literal>@&gt;</literal> <type>anyarray</type>
20068 <returnvalue>boolean</returnvalue>
20069 </para>
20070 <para>
20071 Does the first array contain the second, that is, does each element
20072 appearing in the second array equal some element of the first array?
20073 (Duplicates are not treated specially,
20074 thus <literal>ARRAY[1]</literal> and <literal>ARRAY[1,1]</literal> are
20075 each considered to contain the other.)
20076 </para>
20077 <para>
20078 <literal>ARRAY[1,4,3] @&gt; ARRAY[3,1,3]</literal>
20079 <returnvalue>t</returnvalue>
20080 </para></entry>
20081 </row>
20083 <row>
20084 <entry role="func_table_entry"><para role="func_signature">
20085 <type>anyarray</type> <literal>&lt;@</literal> <type>anyarray</type>
20086 <returnvalue>boolean</returnvalue>
20087 </para>
20088 <para>
20089 Is the first array contained by the second?
20090 </para>
20091 <para>
20092 <literal>ARRAY[2,2,7] &lt;@ ARRAY[1,7,4,2,6]</literal>
20093 <returnvalue>t</returnvalue>
20094 </para></entry>
20095 </row>
20097 <row>
20098 <entry role="func_table_entry"><para role="func_signature">
20099 <type>anyarray</type> <literal>&amp;&amp;</literal> <type>anyarray</type>
20100 <returnvalue>boolean</returnvalue>
20101 </para>
20102 <para>
20103 Do the arrays overlap, that is, have any elements in common?
20104 </para>
20105 <para>
20106 <literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal>
20107 <returnvalue>t</returnvalue>
20108 </para></entry>
20109 </row>
20111 <row>
20112 <entry role="func_table_entry"><para role="func_signature">
20113 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
20114 <returnvalue>anycompatiblearray</returnvalue>
20115 </para>
20116 <para>
20117 Concatenates the two arrays. Concatenating a null or empty array is a
20118 no-op; otherwise the arrays must have the same number of dimensions
20119 (as illustrated by the first example) or differ in number of
20120 dimensions by one (as illustrated by the second).
20121 If the arrays are not of identical element types, they will be coerced
20122 to a common type (see <xref linkend="typeconv-union-case"/>).
20123 </para>
20124 <para>
20125 <literal>ARRAY[1,2,3] || ARRAY[4,5,6,7]</literal>
20126 <returnvalue>{1,2,3,4,5,6,7}</returnvalue>
20127 </para>
20128 <para>
20129 <literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9.9]]</literal>
20130 <returnvalue>{{1,2,3},{4,5,6},{7,8,9.9}}</returnvalue>
20131 </para></entry>
20132 </row>
20134 <row>
20135 <entry role="func_table_entry"><para role="func_signature">
20136 <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
20137 <returnvalue>anycompatiblearray</returnvalue>
20138 </para>
20139 <para>
20140 Concatenates an element onto the front of an array (which must be
20141 empty or one-dimensional).
20142 </para>
20143 <para>
20144 <literal>3 || ARRAY[4,5,6]</literal>
20145 <returnvalue>{3,4,5,6}</returnvalue>
20146 </para></entry>
20147 </row>
20149 <row>
20150 <entry role="func_table_entry"><para role="func_signature">
20151 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
20152 <returnvalue>anycompatiblearray</returnvalue>
20153 </para>
20154 <para>
20155 Concatenates an element onto the end of an array (which must be
20156 empty or one-dimensional).
20157 </para>
20158 <para>
20159 <literal>ARRAY[4,5,6] || 7</literal>
20160 <returnvalue>{4,5,6,7}</returnvalue>
20161 </para></entry>
20162 </row>
20163 </tbody>
20164 </tgroup>
20165 </table>
20167 <para>
20168 See <xref linkend="arrays"/> for more details about array operator
20169 behavior. See <xref linkend="indexes-types"/> for more details about
20170 which operators support indexed operations.
20171 </para>
20173 <para>
20174 <xref linkend="array-functions-table"/> shows the functions
20175 available for use with array types. See <xref linkend="arrays"/>
20176 for more information and examples of the use of these functions.
20177 </para>
20179 <table id="array-functions-table">
20180 <title>Array Functions</title>
20181 <tgroup cols="1">
20182 <thead>
20183 <row>
20184 <entry role="func_table_entry"><para role="func_signature">
20185 Function
20186 </para>
20187 <para>
20188 Description
20189 </para>
20190 <para>
20191 Example(s)
20192 </para></entry>
20193 </row>
20194 </thead>
20196 <tbody>
20197 <row>
20198 <entry role="func_table_entry"><para role="func_signature">
20199 <indexterm>
20200 <primary>array_append</primary>
20201 </indexterm>
20202 <function>array_append</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
20203 <returnvalue>anycompatiblearray</returnvalue>
20204 </para>
20205 <para>
20206 Appends an element to the end of an array (same as
20207 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
20208 operator).
20209 </para>
20210 <para>
20211 <literal>array_append(ARRAY[1,2], 3)</literal>
20212 <returnvalue>{1,2,3}</returnvalue>
20213 </para></entry>
20214 </row>
20216 <row>
20217 <entry role="func_table_entry"><para role="func_signature">
20218 <indexterm>
20219 <primary>array_cat</primary>
20220 </indexterm>
20221 <function>array_cat</function> ( <type>anycompatiblearray</type>, <type>anycompatiblearray</type> )
20222 <returnvalue>anycompatiblearray</returnvalue>
20223 </para>
20224 <para>
20225 Concatenates two arrays (same as
20226 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
20227 operator).
20228 </para>
20229 <para>
20230 <literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal>
20231 <returnvalue>{1,2,3,4,5}</returnvalue>
20232 </para></entry>
20233 </row>
20235 <row>
20236 <entry role="func_table_entry"><para role="func_signature">
20237 <indexterm>
20238 <primary>array_dims</primary>
20239 </indexterm>
20240 <function>array_dims</function> ( <type>anyarray</type> )
20241 <returnvalue>text</returnvalue>
20242 </para>
20243 <para>
20244 Returns a text representation of the array's dimensions.
20245 </para>
20246 <para>
20247 <literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal>
20248 <returnvalue>[1:2][1:3]</returnvalue>
20249 </para></entry>
20250 </row>
20252 <row>
20253 <entry role="func_table_entry"><para role="func_signature">
20254 <indexterm>
20255 <primary>array_fill</primary>
20256 </indexterm>
20257 <function>array_fill</function> ( <type>anyelement</type>, <type>integer[]</type>
20258 <optional>, <type>integer[]</type> </optional> )
20259 <returnvalue>anyarray</returnvalue>
20260 </para>
20261 <para>
20262 Returns an array filled with copies of the given value, having
20263 dimensions of the lengths specified by the second argument.
20264 The optional third argument supplies lower-bound values for each
20265 dimension (which default to all <literal>1</literal>).
20266 </para>
20267 <para>
20268 <literal>array_fill(11, ARRAY[2,3])</literal>
20269 <returnvalue>{{11,11,11},{11,11,11}}</returnvalue>
20270 </para>
20271 <para>
20272 <literal>array_fill(7, ARRAY[3], ARRAY[2])</literal>
20273 <returnvalue>[2:4]={7,7,7}</returnvalue>
20274 </para></entry>
20275 </row>
20277 <row>
20278 <entry role="func_table_entry"><para role="func_signature">
20279 <indexterm>
20280 <primary>array_length</primary>
20281 </indexterm>
20282 <function>array_length</function> ( <type>anyarray</type>, <type>integer</type> )
20283 <returnvalue>integer</returnvalue>
20284 </para>
20285 <para>
20286 Returns the length of the requested array dimension.
20287 (Produces NULL instead of 0 for empty or missing array dimensions.)
20288 </para>
20289 <para>
20290 <literal>array_length(array[1,2,3], 1)</literal>
20291 <returnvalue>3</returnvalue>
20292 </para>
20293 <para>
20294 <literal>array_length(array[]::int[], 1)</literal>
20295 <returnvalue>NULL</returnvalue>
20296 </para>
20297 <para>
20298 <literal>array_length(array['text'], 2)</literal>
20299 <returnvalue>NULL</returnvalue>
20300 </para></entry>
20301 </row>
20303 <row>
20304 <entry role="func_table_entry"><para role="func_signature">
20305 <indexterm>
20306 <primary>array_lower</primary>
20307 </indexterm>
20308 <function>array_lower</function> ( <type>anyarray</type>, <type>integer</type> )
20309 <returnvalue>integer</returnvalue>
20310 </para>
20311 <para>
20312 Returns the lower bound of the requested array dimension.
20313 </para>
20314 <para>
20315 <literal>array_lower('[0:2]={1,2,3}'::integer[], 1)</literal>
20316 <returnvalue>0</returnvalue>
20317 </para></entry>
20318 </row>
20320 <row>
20321 <entry role="func_table_entry"><para role="func_signature">
20322 <indexterm>
20323 <primary>array_ndims</primary>
20324 </indexterm>
20325 <function>array_ndims</function> ( <type>anyarray</type> )
20326 <returnvalue>integer</returnvalue>
20327 </para>
20328 <para>
20329 Returns the number of dimensions of the array.
20330 </para>
20331 <para>
20332 <literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal>
20333 <returnvalue>2</returnvalue>
20334 </para></entry>
20335 </row>
20337 <row>
20338 <entry role="func_table_entry"><para role="func_signature">
20339 <indexterm>
20340 <primary>array_position</primary>
20341 </indexterm>
20342 <function>array_position</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> <optional>, <type>integer</type> </optional> )
20343 <returnvalue>integer</returnvalue>
20344 </para>
20345 <para>
20346 Returns the subscript of the first occurrence of the second argument
20347 in the array, or <literal>NULL</literal> if it's not present.
20348 If the third argument is given, the search begins at that subscript.
20349 The array must be one-dimensional.
20350 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
20351 semantics, so it is possible to search for <literal>NULL</literal>.
20352 </para>
20353 <para>
20354 <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')</literal>
20355 <returnvalue>2</returnvalue>
20356 </para></entry>
20357 </row>
20359 <row>
20360 <entry role="func_table_entry"><para role="func_signature">
20361 <indexterm>
20362 <primary>array_positions</primary>
20363 </indexterm>
20364 <function>array_positions</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
20365 <returnvalue>integer[]</returnvalue>
20366 </para>
20367 <para>
20368 Returns an array of the subscripts of all occurrences of the second
20369 argument in the array given as first argument.
20370 The array must be one-dimensional.
20371 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
20372 semantics, so it is possible to search for <literal>NULL</literal>.
20373 <literal>NULL</literal> is returned only if the array
20374 is <literal>NULL</literal>; if the value is not found in the array, an
20375 empty array is returned.
20376 </para>
20377 <para>
20378 <literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal>
20379 <returnvalue>{1,2,4}</returnvalue>
20380 </para></entry>
20381 </row>
20383 <row>
20384 <entry role="func_table_entry"><para role="func_signature">
20385 <indexterm>
20386 <primary>array_prepend</primary>
20387 </indexterm>
20388 <function>array_prepend</function> ( <type>anycompatible</type>, <type>anycompatiblearray</type> )
20389 <returnvalue>anycompatiblearray</returnvalue>
20390 </para>
20391 <para>
20392 Prepends an element to the beginning of an array (same as
20393 the <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
20394 operator).
20395 </para>
20396 <para>
20397 <literal>array_prepend(1, ARRAY[2,3])</literal>
20398 <returnvalue>{1,2,3}</returnvalue>
20399 </para></entry>
20400 </row>
20402 <row>
20403 <entry role="func_table_entry"><para role="func_signature">
20404 <indexterm>
20405 <primary>array_remove</primary>
20406 </indexterm>
20407 <function>array_remove</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
20408 <returnvalue>anycompatiblearray</returnvalue>
20409 </para>
20410 <para>
20411 Removes all elements equal to the given value from the array.
20412 The array must be one-dimensional.
20413 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
20414 semantics, so it is possible to remove <literal>NULL</literal>s.
20415 </para>
20416 <para>
20417 <literal>array_remove(ARRAY[1,2,3,2], 2)</literal>
20418 <returnvalue>{1,3}</returnvalue>
20419 </para></entry>
20420 </row>
20422 <row>
20423 <entry role="func_table_entry"><para role="func_signature">
20424 <indexterm>
20425 <primary>array_replace</primary>
20426 </indexterm>
20427 <function>array_replace</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type>, <type>anycompatible</type> )
20428 <returnvalue>anycompatiblearray</returnvalue>
20429 </para>
20430 <para>
20431 Replaces each array element equal to the second argument with the
20432 third argument.
20433 </para>
20434 <para>
20435 <literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal>
20436 <returnvalue>{1,2,3,4}</returnvalue>
20437 </para></entry>
20438 </row>
20440 <row>
20441 <entry role="func_table_entry"><para role="func_signature">
20442 <indexterm>
20443 <primary>array_reverse</primary>
20444 </indexterm>
20445 <function>array_reverse</function> ( <type>anyarray</type> )
20446 <returnvalue>anyarray</returnvalue>
20447 </para>
20448 <para>
20449 Reverses the first dimension of the array.
20450 </para>
20451 <para>
20452 <literal>array_reverse(ARRAY[[1,2],[3,4],[5,6]])</literal>
20453 <returnvalue>{{5,6},{3,4},{1,2}}</returnvalue>
20454 </para></entry>
20455 </row>
20457 <row>
20458 <entry role="func_table_entry"><para role="func_signature">
20459 <indexterm>
20460 <primary>array_sample</primary>
20461 </indexterm>
20462 <function>array_sample</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
20463 <returnvalue>anyarray</returnvalue>
20464 </para>
20465 <para>
20466 Returns an array of <parameter>n</parameter> items randomly selected
20467 from <parameter>array</parameter>. <parameter>n</parameter> may not
20468 exceed the length of <parameter>array</parameter>'s first dimension.
20469 If <parameter>array</parameter> is multi-dimensional,
20470 an <quote>item</quote> is a slice having a given first subscript.
20471 </para>
20472 <para>
20473 <literal>array_sample(ARRAY[1,2,3,4,5,6], 3)</literal>
20474 <returnvalue>{2,6,1}</returnvalue>
20475 </para>
20476 <para>
20477 <literal>array_sample(ARRAY[[1,2],[3,4],[5,6]], 2)</literal>
20478 <returnvalue>{{5,6},{1,2}}</returnvalue>
20479 </para></entry>
20480 </row>
20482 <row>
20483 <entry role="func_table_entry"><para role="func_signature">
20484 <indexterm>
20485 <primary>array_shuffle</primary>
20486 </indexterm>
20487 <function>array_shuffle</function> ( <type>anyarray</type> )
20488 <returnvalue>anyarray</returnvalue>
20489 </para>
20490 <para>
20491 Randomly shuffles the first dimension of the array.
20492 </para>
20493 <para>
20494 <literal>array_shuffle(ARRAY[[1,2],[3,4],[5,6]])</literal>
20495 <returnvalue>{{5,6},{1,2},{3,4}}</returnvalue>
20496 </para></entry>
20497 </row>
20499 <row>
20500 <entry role="func_table_entry"><para role="func_signature">
20501 <indexterm id="function-array-to-string">
20502 <primary>array_to_string</primary>
20503 </indexterm>
20504 <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> )
20505 <returnvalue>text</returnvalue>
20506 </para>
20507 <para>
20508 Converts each array element to its text representation, and
20509 concatenates those separated by
20510 the <parameter>delimiter</parameter> string.
20511 If <parameter>null_string</parameter> is given and is
20512 not <literal>NULL</literal>, then <literal>NULL</literal> array
20513 entries are represented by that string; otherwise, they are omitted.
20514 See also <link linkend="function-string-to-array"><function>string_to_array</function></link>.
20515 </para>
20516 <para>
20517 <literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal>
20518 <returnvalue>1,2,3,*,5</returnvalue>
20519 </para></entry>
20520 </row>
20522 <row>
20523 <entry role="func_table_entry"><para role="func_signature">
20524 <indexterm>
20525 <primary>array_upper</primary>
20526 </indexterm>
20527 <function>array_upper</function> ( <type>anyarray</type>, <type>integer</type> )
20528 <returnvalue>integer</returnvalue>
20529 </para>
20530 <para>
20531 Returns the upper bound of the requested array dimension.
20532 </para>
20533 <para>
20534 <literal>array_upper(ARRAY[1,8,3,7], 1)</literal>
20535 <returnvalue>4</returnvalue>
20536 </para></entry>
20537 </row>
20539 <row>
20540 <entry role="func_table_entry"><para role="func_signature">
20541 <indexterm>
20542 <primary>cardinality</primary>
20543 </indexterm>
20544 <function>cardinality</function> ( <type>anyarray</type> )
20545 <returnvalue>integer</returnvalue>
20546 </para>
20547 <para>
20548 Returns the total number of elements in the array, or 0 if the array
20549 is empty.
20550 </para>
20551 <para>
20552 <literal>cardinality(ARRAY[[1,2],[3,4]])</literal>
20553 <returnvalue>4</returnvalue>
20554 </para></entry>
20555 </row>
20557 <row>
20558 <entry role="func_table_entry"><para role="func_signature">
20559 <indexterm>
20560 <primary>trim_array</primary>
20561 </indexterm>
20562 <function>trim_array</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
20563 <returnvalue>anyarray</returnvalue>
20564 </para>
20565 <para>
20566 Trims an array by removing the last <parameter>n</parameter> elements.
20567 If the array is multidimensional, only the first dimension is trimmed.
20568 </para>
20569 <para>
20570 <literal>trim_array(ARRAY[1,2,3,4,5,6], 2)</literal>
20571 <returnvalue>{1,2,3,4}</returnvalue>
20572 </para></entry>
20573 </row>
20575 <row>
20576 <entry role="func_table_entry"><para role="func_signature">
20577 <indexterm>
20578 <primary>unnest</primary>
20579 </indexterm>
20580 <function>unnest</function> ( <type>anyarray</type> )
20581 <returnvalue>setof anyelement</returnvalue>
20582 </para>
20583 <para>
20584 Expands an array into a set of rows.
20585 The array's elements are read out in storage order.
20586 </para>
20587 <para>
20588 <literal>unnest(ARRAY[1,2])</literal>
20589 <returnvalue></returnvalue>
20590 <programlisting>
20593 </programlisting>
20594 </para>
20595 <para>
20596 <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])</literal>
20597 <returnvalue></returnvalue>
20598 <programlisting>
20602 quux
20603 </programlisting>
20604 </para></entry>
20605 </row>
20607 <row>
20608 <entry role="func_table_entry"><para role="func_signature">
20609 <function>unnest</function> ( <type>anyarray</type>, <type>anyarray</type> <optional>, ... </optional> )
20610 <returnvalue>setof anyelement, anyelement [, ... ]</returnvalue>
20611 </para>
20612 <para>
20613 Expands multiple arrays (possibly of different data types) into a set of
20614 rows. If the arrays are not all the same length then the shorter ones
20615 are padded with <literal>NULL</literal>s. This form is only allowed
20616 in a query's FROM clause; see <xref linkend="queries-tablefunctions"/>.
20617 </para>
20618 <para>
20619 <literal>select * from unnest(ARRAY[1,2], ARRAY['foo','bar','baz']) as x(a,b)</literal>
20620 <returnvalue></returnvalue>
20621 <programlisting>
20622 a | b
20623 ---+-----
20624 1 | foo
20625 2 | bar
20626 | baz
20627 </programlisting>
20628 </para></entry>
20629 </row>
20630 </tbody>
20631 </tgroup>
20632 </table>
20634 <para>
20635 See also <xref linkend="functions-aggregate"/> about the aggregate
20636 function <function>array_agg</function> for use with arrays.
20637 </para>
20638 </sect1>
20640 <sect1 id="functions-range">
20641 <title>Range/Multirange Functions and Operators</title>
20643 <para>
20644 See <xref linkend="rangetypes"/> for an overview of range types.
20645 </para>
20647 <para>
20648 <xref linkend="range-operators-table"/> shows the specialized operators
20649 available for range types.
20650 <xref linkend="multirange-operators-table"/> shows the specialized operators
20651 available for multirange types.
20652 In addition to those, the usual comparison operators shown in
20653 <xref linkend="functions-comparison-op-table"/> are available for range
20654 and multirange types. The comparison operators order first by the range lower
20655 bounds, and only if those are equal do they compare the upper bounds. The
20656 multirange operators compare each range until one is unequal. This
20657 does not usually result in a useful overall ordering, but the operators are
20658 provided to allow unique indexes to be constructed on ranges.
20659 </para>
20661 <table id="range-operators-table">
20662 <title>Range Operators</title>
20663 <tgroup cols="1">
20664 <thead>
20665 <row>
20666 <entry role="func_table_entry"><para role="func_signature">
20667 Operator
20668 </para>
20669 <para>
20670 Description
20671 </para>
20672 <para>
20673 Example(s)
20674 </para></entry>
20675 </row>
20676 </thead>
20678 <tbody>
20679 <row>
20680 <entry role="func_table_entry"><para role="func_signature">
20681 <type>anyrange</type> <literal>@&gt;</literal> <type>anyrange</type>
20682 <returnvalue>boolean</returnvalue>
20683 </para>
20684 <para>
20685 Does the first range contain the second?
20686 </para>
20687 <para>
20688 <literal>int4range(2,4) @&gt; int4range(2,3)</literal>
20689 <returnvalue>t</returnvalue>
20690 </para></entry>
20691 </row>
20693 <row>
20694 <entry role="func_table_entry"><para role="func_signature">
20695 <type>anyrange</type> <literal>@&gt;</literal> <type>anyelement</type>
20696 <returnvalue>boolean</returnvalue>
20697 </para>
20698 <para>
20699 Does the range contain the element?
20700 </para>
20701 <para>
20702 <literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal>
20703 <returnvalue>t</returnvalue>
20704 </para></entry>
20705 </row>
20707 <row>
20708 <entry role="func_table_entry"><para role="func_signature">
20709 <type>anyrange</type> <literal>&lt;@</literal> <type>anyrange</type>
20710 <returnvalue>boolean</returnvalue>
20711 </para>
20712 <para>
20713 Is the first range contained by the second?
20714 </para>
20715 <para>
20716 <literal>int4range(2,4) &lt;@ int4range(1,7)</literal>
20717 <returnvalue>t</returnvalue>
20718 </para></entry>
20719 </row>
20721 <row>
20722 <entry role="func_table_entry"><para role="func_signature">
20723 <type>anyelement</type> <literal>&lt;@</literal> <type>anyrange</type>
20724 <returnvalue>boolean</returnvalue>
20725 </para>
20726 <para>
20727 Is the element contained in the range?
20728 </para>
20729 <para>
20730 <literal>42 &lt;@ int4range(1,7)</literal>
20731 <returnvalue>f</returnvalue>
20732 </para></entry>
20733 </row>
20735 <row>
20736 <entry role="func_table_entry"><para role="func_signature">
20737 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
20738 <returnvalue>boolean</returnvalue>
20739 </para>
20740 <para>
20741 Do the ranges overlap, that is, have any elements in common?
20742 </para>
20743 <para>
20744 <literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal>
20745 <returnvalue>t</returnvalue>
20746 </para></entry>
20747 </row>
20749 <row>
20750 <entry role="func_table_entry"><para role="func_signature">
20751 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
20752 <returnvalue>boolean</returnvalue>
20753 </para>
20754 <para>
20755 Is the first range strictly left of the second?
20756 </para>
20757 <para>
20758 <literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal>
20759 <returnvalue>t</returnvalue>
20760 </para></entry>
20761 </row>
20763 <row>
20764 <entry role="func_table_entry"><para role="func_signature">
20765 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
20766 <returnvalue>boolean</returnvalue>
20767 </para>
20768 <para>
20769 Is the first range strictly right of the second?
20770 </para>
20771 <para>
20772 <literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal>
20773 <returnvalue>t</returnvalue>
20774 </para></entry>
20775 </row>
20777 <row>
20778 <entry role="func_table_entry"><para role="func_signature">
20779 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
20780 <returnvalue>boolean</returnvalue>
20781 </para>
20782 <para>
20783 Does the first range not extend to the right of the second?
20784 </para>
20785 <para>
20786 <literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal>
20787 <returnvalue>t</returnvalue>
20788 </para></entry>
20789 </row>
20791 <row>
20792 <entry role="func_table_entry"><para role="func_signature">
20793 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
20794 <returnvalue>boolean</returnvalue>
20795 </para>
20796 <para>
20797 Does the first range not extend to the left of the second?
20798 </para>
20799 <para>
20800 <literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal>
20801 <returnvalue>t</returnvalue>
20802 </para></entry>
20803 </row>
20805 <row>
20806 <entry role="func_table_entry"><para role="func_signature">
20807 <type>anyrange</type> <literal>-|-</literal> <type>anyrange</type>
20808 <returnvalue>boolean</returnvalue>
20809 </para>
20810 <para>
20811 Are the ranges adjacent?
20812 </para>
20813 <para>
20814 <literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal>
20815 <returnvalue>t</returnvalue>
20816 </para></entry>
20817 </row>
20819 <row>
20820 <entry role="func_table_entry"><para role="func_signature">
20821 <type>anyrange</type> <literal>+</literal> <type>anyrange</type>
20822 <returnvalue>anyrange</returnvalue>
20823 </para>
20824 <para>
20825 Computes the union of the ranges. The ranges must overlap or be
20826 adjacent, so that the union is a single range (but
20827 see <function>range_merge()</function>).
20828 </para>
20829 <para>
20830 <literal>numrange(5,15) + numrange(10,20)</literal>
20831 <returnvalue>[5,20)</returnvalue>
20832 </para></entry>
20833 </row>
20835 <row>
20836 <entry role="func_table_entry"><para role="func_signature">
20837 <type>anyrange</type> <literal>*</literal> <type>anyrange</type>
20838 <returnvalue>anyrange</returnvalue>
20839 </para>
20840 <para>
20841 Computes the intersection of the ranges.
20842 </para>
20843 <para>
20844 <literal>int8range(5,15) * int8range(10,20)</literal>
20845 <returnvalue>[10,15)</returnvalue>
20846 </para></entry>
20847 </row>
20849 <row>
20850 <entry role="func_table_entry"><para role="func_signature">
20851 <type>anyrange</type> <literal>-</literal> <type>anyrange</type>
20852 <returnvalue>anyrange</returnvalue>
20853 </para>
20854 <para>
20855 Computes the difference of the ranges. The second range must not be
20856 contained in the first in such a way that the difference would not be
20857 a single range.
20858 </para>
20859 <para>
20860 <literal>int8range(5,15) - int8range(10,20)</literal>
20861 <returnvalue>[5,10)</returnvalue>
20862 </para></entry>
20863 </row>
20864 </tbody>
20865 </tgroup>
20866 </table>
20868 <table id="multirange-operators-table">
20869 <title>Multirange Operators</title>
20870 <tgroup cols="1">
20871 <thead>
20872 <row>
20873 <entry role="func_table_entry"><para role="func_signature">
20874 Operator
20875 </para>
20876 <para>
20877 Description
20878 </para>
20879 <para>
20880 Example(s)
20881 </para></entry>
20882 </row>
20883 </thead>
20885 <tbody>
20886 <row>
20887 <entry role="func_table_entry"><para role="func_signature">
20888 <type>anymultirange</type> <literal>@&gt;</literal> <type>anymultirange</type>
20889 <returnvalue>boolean</returnvalue>
20890 </para>
20891 <para>
20892 Does the first multirange contain the second?
20893 </para>
20894 <para>
20895 <literal>'{[2,4)}'::int4multirange @&gt; '{[2,3)}'::int4multirange</literal>
20896 <returnvalue>t</returnvalue>
20897 </para></entry>
20898 </row>
20900 <row>
20901 <entry role="func_table_entry"><para role="func_signature">
20902 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyrange</type>
20903 <returnvalue>boolean</returnvalue>
20904 </para>
20905 <para>
20906 Does the multirange contain the range?
20907 </para>
20908 <para>
20909 <literal>'{[2,4)}'::int4multirange @&gt; int4range(2,3)</literal>
20910 <returnvalue>t</returnvalue>
20911 </para></entry>
20912 </row>
20914 <row>
20915 <entry role="func_table_entry"><para role="func_signature">
20916 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyelement</type>
20917 <returnvalue>boolean</returnvalue>
20918 </para>
20919 <para>
20920 Does the multirange contain the element?
20921 </para>
20922 <para>
20923 <literal>'{[2011-01-01,2011-03-01)}'::tsmultirange @&gt; '2011-01-10'::timestamp</literal>
20924 <returnvalue>t</returnvalue>
20925 </para></entry>
20926 </row>
20928 <row>
20929 <entry role="func_table_entry"><para role="func_signature">
20930 <type>anyrange</type> <literal>@&gt;</literal> <type>anymultirange</type>
20931 <returnvalue>boolean</returnvalue>
20932 </para>
20933 <para>
20934 Does the range contain the multirange?
20935 </para>
20936 <para>
20937 <literal>'[2,4)'::int4range @&gt; '{[2,3)}'::int4multirange</literal>
20938 <returnvalue>t</returnvalue>
20939 </para></entry>
20940 </row>
20942 <row>
20943 <entry role="func_table_entry"><para role="func_signature">
20944 <type>anymultirange</type> <literal>&lt;@</literal> <type>anymultirange</type>
20945 <returnvalue>boolean</returnvalue>
20946 </para>
20947 <para>
20948 Is the first multirange contained by the second?
20949 </para>
20950 <para>
20951 <literal>'{[2,4)}'::int4multirange &lt;@ '{[1,7)}'::int4multirange</literal>
20952 <returnvalue>t</returnvalue>
20953 </para></entry>
20954 </row>
20956 <row>
20957 <entry role="func_table_entry"><para role="func_signature">
20958 <type>anymultirange</type> <literal>&lt;@</literal> <type>anyrange</type>
20959 <returnvalue>boolean</returnvalue>
20960 </para>
20961 <para>
20962 Is the multirange contained by the range?
20963 </para>
20964 <para>
20965 <literal>'{[2,4)}'::int4multirange &lt;@ int4range(1,7)</literal>
20966 <returnvalue>t</returnvalue>
20967 </para></entry>
20968 </row>
20970 <row>
20971 <entry role="func_table_entry"><para role="func_signature">
20972 <type>anyrange</type> <literal>&lt;@</literal> <type>anymultirange</type>
20973 <returnvalue>boolean</returnvalue>
20974 </para>
20975 <para>
20976 Is the range contained by the multirange?
20977 </para>
20978 <para>
20979 <literal>int4range(2,4) &lt;@ '{[1,7)}'::int4multirange</literal>
20980 <returnvalue>t</returnvalue>
20981 </para></entry>
20982 </row>
20984 <row>
20985 <entry role="func_table_entry"><para role="func_signature">
20986 <type>anyelement</type> <literal>&lt;@</literal> <type>anymultirange</type>
20987 <returnvalue>boolean</returnvalue>
20988 </para>
20989 <para>
20990 Is the element contained by the multirange?
20991 </para>
20992 <para>
20993 <literal>4 &lt;@ '{[1,7)}'::int4multirange</literal>
20994 <returnvalue>t</returnvalue>
20995 </para></entry>
20996 </row>
20998 <row>
20999 <entry role="func_table_entry"><para role="func_signature">
21000 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
21001 <returnvalue>boolean</returnvalue>
21002 </para>
21003 <para>
21004 Do the multiranges overlap, that is, have any elements in common?
21005 </para>
21006 <para>
21007 <literal>'{[3,7)}'::int8multirange &amp;&amp; '{[4,12)}'::int8multirange</literal>
21008 <returnvalue>t</returnvalue>
21009 </para></entry>
21010 </row>
21012 <row>
21013 <entry role="func_table_entry"><para role="func_signature">
21014 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
21015 <returnvalue>boolean</returnvalue>
21016 </para>
21017 <para>
21018 Does the multirange overlap the range?
21019 </para>
21020 <para>
21021 <literal>'{[3,7)}'::int8multirange &amp;&amp; int8range(4,12)</literal>
21022 <returnvalue>t</returnvalue>
21023 </para></entry>
21024 </row>
21026 <row>
21027 <entry role="func_table_entry"><para role="func_signature">
21028 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
21029 <returnvalue>boolean</returnvalue>
21030 </para>
21031 <para>
21032 Does the range overlap the multirange?
21033 </para>
21034 <para>
21035 <literal>int8range(3,7) &amp;&amp; '{[4,12)}'::int8multirange</literal>
21036 <returnvalue>t</returnvalue>
21037 </para></entry>
21038 </row>
21040 <row>
21041 <entry role="func_table_entry"><para role="func_signature">
21042 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
21043 <returnvalue>boolean</returnvalue>
21044 </para>
21045 <para>
21046 Is the first multirange strictly left of the second?
21047 </para>
21048 <para>
21049 <literal>'{[1,10)}'::int8multirange &lt;&lt; '{[100,110)}'::int8multirange</literal>
21050 <returnvalue>t</returnvalue>
21051 </para></entry>
21052 </row>
21054 <row>
21055 <entry role="func_table_entry"><para role="func_signature">
21056 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
21057 <returnvalue>boolean</returnvalue>
21058 </para>
21059 <para>
21060 Is the multirange strictly left of the range?
21061 </para>
21062 <para>
21063 <literal>'{[1,10)}'::int8multirange &lt;&lt; int8range(100,110)</literal>
21064 <returnvalue>t</returnvalue>
21065 </para></entry>
21066 </row>
21068 <row>
21069 <entry role="func_table_entry"><para role="func_signature">
21070 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
21071 <returnvalue>boolean</returnvalue>
21072 </para>
21073 <para>
21074 Is the range strictly left of the multirange?
21075 </para>
21076 <para>
21077 <literal>int8range(1,10) &lt;&lt; '{[100,110)}'::int8multirange</literal>
21078 <returnvalue>t</returnvalue>
21079 </para></entry>
21080 </row>
21082 <row>
21083 <entry role="func_table_entry"><para role="func_signature">
21084 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
21085 <returnvalue>boolean</returnvalue>
21086 </para>
21087 <para>
21088 Is the first multirange strictly right of the second?
21089 </para>
21090 <para>
21091 <literal>'{[50,60)}'::int8multirange &gt;&gt; '{[20,30)}'::int8multirange</literal>
21092 <returnvalue>t</returnvalue>
21093 </para></entry>
21094 </row>
21096 <row>
21097 <entry role="func_table_entry"><para role="func_signature">
21098 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
21099 <returnvalue>boolean</returnvalue>
21100 </para>
21101 <para>
21102 Is the multirange strictly right of the range?
21103 </para>
21104 <para>
21105 <literal>'{[50,60)}'::int8multirange &gt;&gt; int8range(20,30)</literal>
21106 <returnvalue>t</returnvalue>
21107 </para></entry>
21108 </row>
21110 <row>
21111 <entry role="func_table_entry"><para role="func_signature">
21112 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
21113 <returnvalue>boolean</returnvalue>
21114 </para>
21115 <para>
21116 Is the range strictly right of the multirange?
21117 </para>
21118 <para>
21119 <literal>int8range(50,60) &gt;&gt; '{[20,30)}'::int8multirange</literal>
21120 <returnvalue>t</returnvalue>
21121 </para></entry>
21122 </row>
21124 <row>
21125 <entry role="func_table_entry"><para role="func_signature">
21126 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
21127 <returnvalue>boolean</returnvalue>
21128 </para>
21129 <para>
21130 Does the first multirange not extend to the right of the second?
21131 </para>
21132 <para>
21133 <literal>'{[1,20)}'::int8multirange &amp;&lt; '{[18,20)}'::int8multirange</literal>
21134 <returnvalue>t</returnvalue>
21135 </para></entry>
21136 </row>
21138 <row>
21139 <entry role="func_table_entry"><para role="func_signature">
21140 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
21141 <returnvalue>boolean</returnvalue>
21142 </para>
21143 <para>
21144 Does the multirange not extend to the right of the range?
21145 </para>
21146 <para>
21147 <literal>'{[1,20)}'::int8multirange &amp;&lt; int8range(18,20)</literal>
21148 <returnvalue>t</returnvalue>
21149 </para></entry>
21150 </row>
21152 <row>
21153 <entry role="func_table_entry"><para role="func_signature">
21154 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
21155 <returnvalue>boolean</returnvalue>
21156 </para>
21157 <para>
21158 Does the range not extend to the right of the multirange?
21159 </para>
21160 <para>
21161 <literal>int8range(1,20) &amp;&lt; '{[18,20)}'::int8multirange</literal>
21162 <returnvalue>t</returnvalue>
21163 </para></entry>
21164 </row>
21166 <row>
21167 <entry role="func_table_entry"><para role="func_signature">
21168 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
21169 <returnvalue>boolean</returnvalue>
21170 </para>
21171 <para>
21172 Does the first multirange not extend to the left of the second?
21173 </para>
21174 <para>
21175 <literal>'{[7,20)}'::int8multirange &amp;&gt; '{[5,10)}'::int8multirange</literal>
21176 <returnvalue>t</returnvalue>
21177 </para></entry>
21178 </row>
21180 <row>
21181 <entry role="func_table_entry"><para role="func_signature">
21182 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
21183 <returnvalue>boolean</returnvalue>
21184 </para>
21185 <para>
21186 Does the multirange not extend to the left of the range?
21187 </para>
21188 <para>
21189 <literal>'{[7,20)}'::int8multirange &amp;&gt; int8range(5,10)</literal>
21190 <returnvalue>t</returnvalue>
21191 </para></entry>
21192 </row>
21194 <row>
21195 <entry role="func_table_entry"><para role="func_signature">
21196 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
21197 <returnvalue>boolean</returnvalue>
21198 </para>
21199 <para>
21200 Does the range not extend to the left of the multirange?
21201 </para>
21202 <para>
21203 <literal>int8range(7,20) &amp;&gt; '{[5,10)}'::int8multirange</literal>
21204 <returnvalue>t</returnvalue>
21205 </para></entry>
21206 </row>
21208 <row>
21209 <entry role="func_table_entry"><para role="func_signature">
21210 <type>anymultirange</type> <literal>-|-</literal> <type>anymultirange</type>
21211 <returnvalue>boolean</returnvalue>
21212 </para>
21213 <para>
21214 Are the multiranges adjacent?
21215 </para>
21216 <para>
21217 <literal>'{[1.1,2.2)}'::nummultirange -|- '{[2.2,3.3)}'::nummultirange</literal>
21218 <returnvalue>t</returnvalue>
21219 </para></entry>
21220 </row>
21222 <row>
21223 <entry role="func_table_entry"><para role="func_signature">
21224 <type>anymultirange</type> <literal>-|-</literal> <type>anyrange</type>
21225 <returnvalue>boolean</returnvalue>
21226 </para>
21227 <para>
21228 Is the multirange adjacent to the range?
21229 </para>
21230 <para>
21231 <literal>'{[1.1,2.2)}'::nummultirange -|- numrange(2.2,3.3)</literal>
21232 <returnvalue>t</returnvalue>
21233 </para></entry>
21234 </row>
21236 <row>
21237 <entry role="func_table_entry"><para role="func_signature">
21238 <type>anyrange</type> <literal>-|-</literal> <type>anymultirange</type>
21239 <returnvalue>boolean</returnvalue>
21240 </para>
21241 <para>
21242 Is the range adjacent to the multirange?
21243 </para>
21244 <para>
21245 <literal>numrange(1.1,2.2) -|- '{[2.2,3.3)}'::nummultirange</literal>
21246 <returnvalue>t</returnvalue>
21247 </para></entry>
21248 </row>
21250 <row>
21251 <entry role="func_table_entry"><para role="func_signature">
21252 <type>anymultirange</type> <literal>+</literal> <type>anymultirange</type>
21253 <returnvalue>anymultirange</returnvalue>
21254 </para>
21255 <para>
21256 Computes the union of the multiranges. The multiranges need not overlap
21257 or be adjacent.
21258 </para>
21259 <para>
21260 <literal>'{[5,10)}'::nummultirange + '{[15,20)}'::nummultirange</literal>
21261 <returnvalue>{[5,10), [15,20)}</returnvalue>
21262 </para></entry>
21263 </row>
21265 <row>
21266 <entry role="func_table_entry"><para role="func_signature">
21267 <type>anymultirange</type> <literal>*</literal> <type>anymultirange</type>
21268 <returnvalue>anymultirange</returnvalue>
21269 </para>
21270 <para>
21271 Computes the intersection of the multiranges.
21272 </para>
21273 <para>
21274 <literal>'{[5,15)}'::int8multirange * '{[10,20)}'::int8multirange</literal>
21275 <returnvalue>{[10,15)}</returnvalue>
21276 </para></entry>
21277 </row>
21279 <row>
21280 <entry role="func_table_entry"><para role="func_signature">
21281 <type>anymultirange</type> <literal>-</literal> <type>anymultirange</type>
21282 <returnvalue>anymultirange</returnvalue>
21283 </para>
21284 <para>
21285 Computes the difference of the multiranges.
21286 </para>
21287 <para>
21288 <literal>'{[5,20)}'::int8multirange - '{[10,15)}'::int8multirange</literal>
21289 <returnvalue>{[5,10), [15,20)}</returnvalue>
21290 </para></entry>
21291 </row>
21292 </tbody>
21293 </tgroup>
21294 </table>
21296 <para>
21297 The left-of/right-of/adjacent operators always return false when an empty
21298 range or multirange is involved; that is, an empty range is not considered to
21299 be either before or after any other range.
21300 </para>
21302 <para>
21303 Elsewhere empty ranges and multiranges are treated as the additive identity:
21304 anything unioned with an empty value is itself. Anything minus an empty
21305 value is itself. An empty multirange has exactly the same points as an empty
21306 range. Every range contains the empty range. Every multirange contains as many
21307 empty ranges as you like.
21308 </para>
21310 <para>
21311 The range union and difference operators will fail if the resulting range would
21312 need to contain two disjoint sub-ranges, as such a range cannot be
21313 represented. There are separate operators for union and difference that take
21314 multirange parameters and return a multirange, and they do not fail even if
21315 their arguments are disjoint. So if you need a union or difference operation
21316 for ranges that may be disjoint, you can avoid errors by first casting your
21317 ranges to multiranges.
21318 </para>
21320 <para>
21321 <xref linkend="range-functions-table"/> shows the functions
21322 available for use with range types.
21323 <xref linkend="multirange-functions-table"/> shows the functions
21324 available for use with multirange types.
21325 </para>
21327 <table id="range-functions-table">
21328 <title>Range Functions</title>
21329 <tgroup cols="1">
21330 <thead>
21331 <row>
21332 <entry role="func_table_entry"><para role="func_signature">
21333 Function
21334 </para>
21335 <para>
21336 Description
21337 </para>
21338 <para>
21339 Example(s)
21340 </para></entry>
21341 </row>
21342 </thead>
21344 <tbody>
21345 <row>
21346 <entry role="func_table_entry"><para role="func_signature">
21347 <indexterm>
21348 <primary>lower</primary>
21349 </indexterm>
21350 <function>lower</function> ( <type>anyrange</type> )
21351 <returnvalue>anyelement</returnvalue>
21352 </para>
21353 <para>
21354 Extracts the lower bound of the range (<literal>NULL</literal> if the
21355 range is empty or has no lower bound).
21356 </para>
21357 <para>
21358 <literal>lower(numrange(1.1,2.2))</literal>
21359 <returnvalue>1.1</returnvalue>
21360 </para></entry>
21361 </row>
21363 <row>
21364 <entry role="func_table_entry"><para role="func_signature">
21365 <indexterm>
21366 <primary>upper</primary>
21367 </indexterm>
21368 <function>upper</function> ( <type>anyrange</type> )
21369 <returnvalue>anyelement</returnvalue>
21370 </para>
21371 <para>
21372 Extracts the upper bound of the range (<literal>NULL</literal> if the
21373 range is empty or has no upper bound).
21374 </para>
21375 <para>
21376 <literal>upper(numrange(1.1,2.2))</literal>
21377 <returnvalue>2.2</returnvalue>
21378 </para></entry>
21379 </row>
21381 <row>
21382 <entry role="func_table_entry"><para role="func_signature">
21383 <indexterm>
21384 <primary>isempty</primary>
21385 </indexterm>
21386 <function>isempty</function> ( <type>anyrange</type> )
21387 <returnvalue>boolean</returnvalue>
21388 </para>
21389 <para>
21390 Is the range empty?
21391 </para>
21392 <para>
21393 <literal>isempty(numrange(1.1,2.2))</literal>
21394 <returnvalue>f</returnvalue>
21395 </para></entry>
21396 </row>
21398 <row>
21399 <entry role="func_table_entry"><para role="func_signature">
21400 <indexterm>
21401 <primary>lower_inc</primary>
21402 </indexterm>
21403 <function>lower_inc</function> ( <type>anyrange</type> )
21404 <returnvalue>boolean</returnvalue>
21405 </para>
21406 <para>
21407 Is the range's lower bound inclusive?
21408 </para>
21409 <para>
21410 <literal>lower_inc(numrange(1.1,2.2))</literal>
21411 <returnvalue>t</returnvalue>
21412 </para></entry>
21413 </row>
21415 <row>
21416 <entry role="func_table_entry"><para role="func_signature">
21417 <indexterm>
21418 <primary>upper_inc</primary>
21419 </indexterm>
21420 <function>upper_inc</function> ( <type>anyrange</type> )
21421 <returnvalue>boolean</returnvalue>
21422 </para>
21423 <para>
21424 Is the range's upper bound inclusive?
21425 </para>
21426 <para>
21427 <literal>upper_inc(numrange(1.1,2.2))</literal>
21428 <returnvalue>f</returnvalue>
21429 </para></entry>
21430 </row>
21432 <row>
21433 <entry role="func_table_entry"><para role="func_signature">
21434 <indexterm>
21435 <primary>lower_inf</primary>
21436 </indexterm>
21437 <function>lower_inf</function> ( <type>anyrange</type> )
21438 <returnvalue>boolean</returnvalue>
21439 </para>
21440 <para>
21441 Does the range have no lower bound? (A lower bound of
21442 <literal>-Infinity</literal> returns false.)
21443 </para>
21444 <para>
21445 <literal>lower_inf('(,)'::daterange)</literal>
21446 <returnvalue>t</returnvalue>
21447 </para></entry>
21448 </row>
21450 <row>
21451 <entry role="func_table_entry"><para role="func_signature">
21452 <indexterm>
21453 <primary>upper_inf</primary>
21454 </indexterm>
21455 <function>upper_inf</function> ( <type>anyrange</type> )
21456 <returnvalue>boolean</returnvalue>
21457 </para>
21458 <para>
21459 Does the range have no upper bound? (An upper bound of
21460 <literal>Infinity</literal> returns false.)
21461 </para>
21462 <para>
21463 <literal>upper_inf('(,)'::daterange)</literal>
21464 <returnvalue>t</returnvalue>
21465 </para></entry>
21466 </row>
21468 <row>
21469 <entry role="func_table_entry"><para role="func_signature">
21470 <indexterm>
21471 <primary>range_merge</primary>
21472 </indexterm>
21473 <function>range_merge</function> ( <type>anyrange</type>, <type>anyrange</type> )
21474 <returnvalue>anyrange</returnvalue>
21475 </para>
21476 <para>
21477 Computes the smallest range that includes both of the given ranges.
21478 </para>
21479 <para>
21480 <literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal>
21481 <returnvalue>[1,4)</returnvalue>
21482 </para></entry>
21483 </row>
21484 </tbody>
21485 </tgroup>
21486 </table>
21488 <table id="multirange-functions-table">
21489 <title>Multirange Functions</title>
21490 <tgroup cols="1">
21491 <thead>
21492 <row>
21493 <entry role="func_table_entry"><para role="func_signature">
21494 Function
21495 </para>
21496 <para>
21497 Description
21498 </para>
21499 <para>
21500 Example(s)
21501 </para></entry>
21502 </row>
21503 </thead>
21504 <tbody>
21505 <row>
21506 <entry role="func_table_entry"><para role="func_signature">
21507 <indexterm>
21508 <primary>lower</primary>
21509 </indexterm>
21510 <function>lower</function> ( <type>anymultirange</type> )
21511 <returnvalue>anyelement</returnvalue>
21512 </para>
21513 <para>
21514 Extracts the lower bound of the multirange (<literal>NULL</literal> if the
21515 multirange is empty or has no lower bound).
21516 </para>
21517 <para>
21518 <literal>lower('{[1.1,2.2)}'::nummultirange)</literal>
21519 <returnvalue>1.1</returnvalue>
21520 </para></entry>
21521 </row>
21523 <row>
21524 <entry role="func_table_entry"><para role="func_signature">
21525 <indexterm>
21526 <primary>upper</primary>
21527 </indexterm>
21528 <function>upper</function> ( <type>anymultirange</type> )
21529 <returnvalue>anyelement</returnvalue>
21530 </para>
21531 <para>
21532 Extracts the upper bound of the multirange (<literal>NULL</literal> if the
21533 multirange is empty or has no upper bound).
21534 </para>
21535 <para>
21536 <literal>upper('{[1.1,2.2)}'::nummultirange)</literal>
21537 <returnvalue>2.2</returnvalue>
21538 </para></entry>
21539 </row>
21541 <row>
21542 <entry role="func_table_entry"><para role="func_signature">
21543 <indexterm>
21544 <primary>isempty</primary>
21545 </indexterm>
21546 <function>isempty</function> ( <type>anymultirange</type> )
21547 <returnvalue>boolean</returnvalue>
21548 </para>
21549 <para>
21550 Is the multirange empty?
21551 </para>
21552 <para>
21553 <literal>isempty('{[1.1,2.2)}'::nummultirange)</literal>
21554 <returnvalue>f</returnvalue>
21555 </para></entry>
21556 </row>
21558 <row>
21559 <entry role="func_table_entry"><para role="func_signature">
21560 <indexterm>
21561 <primary>lower_inc</primary>
21562 </indexterm>
21563 <function>lower_inc</function> ( <type>anymultirange</type> )
21564 <returnvalue>boolean</returnvalue>
21565 </para>
21566 <para>
21567 Is the multirange's lower bound inclusive?
21568 </para>
21569 <para>
21570 <literal>lower_inc('{[1.1,2.2)}'::nummultirange)</literal>
21571 <returnvalue>t</returnvalue>
21572 </para></entry>
21573 </row>
21575 <row>
21576 <entry role="func_table_entry"><para role="func_signature">
21577 <indexterm>
21578 <primary>upper_inc</primary>
21579 </indexterm>
21580 <function>upper_inc</function> ( <type>anymultirange</type> )
21581 <returnvalue>boolean</returnvalue>
21582 </para>
21583 <para>
21584 Is the multirange's upper bound inclusive?
21585 </para>
21586 <para>
21587 <literal>upper_inc('{[1.1,2.2)}'::nummultirange)</literal>
21588 <returnvalue>f</returnvalue>
21589 </para></entry>
21590 </row>
21592 <row>
21593 <entry role="func_table_entry"><para role="func_signature">
21594 <indexterm>
21595 <primary>lower_inf</primary>
21596 </indexterm>
21597 <function>lower_inf</function> ( <type>anymultirange</type> )
21598 <returnvalue>boolean</returnvalue>
21599 </para>
21600 <para>
21601 Does the multirange have no lower bound? (A lower bound of
21602 <literal>-Infinity</literal> returns false.)
21603 </para>
21604 <para>
21605 <literal>lower_inf('{(,)}'::datemultirange)</literal>
21606 <returnvalue>t</returnvalue>
21607 </para></entry>
21608 </row>
21610 <row>
21611 <entry role="func_table_entry"><para role="func_signature">
21612 <indexterm>
21613 <primary>upper_inf</primary>
21614 </indexterm>
21615 <function>upper_inf</function> ( <type>anymultirange</type> )
21616 <returnvalue>boolean</returnvalue>
21617 </para>
21618 <para>
21619 Does the multirange have no upper bound? (An upper bound of
21620 <literal>Infinity</literal> returns false.)
21621 </para>
21622 <para>
21623 <literal>upper_inf('{(,)}'::datemultirange)</literal>
21624 <returnvalue>t</returnvalue>
21625 </para></entry>
21626 </row>
21628 <row>
21629 <entry role="func_table_entry"><para role="func_signature">
21630 <indexterm>
21631 <primary>range_merge</primary>
21632 </indexterm>
21633 <function>range_merge</function> ( <type>anymultirange</type> )
21634 <returnvalue>anyrange</returnvalue>
21635 </para>
21636 <para>
21637 Computes the smallest range that includes the entire multirange.
21638 </para>
21639 <para>
21640 <literal>range_merge('{[1,2), [3,4)}'::int4multirange)</literal>
21641 <returnvalue>[1,4)</returnvalue>
21642 </para></entry>
21643 </row>
21645 <row>
21646 <entry role="func_table_entry"><para role="func_signature">
21647 <indexterm>
21648 <primary>multirange (function)</primary>
21649 </indexterm>
21650 <function>multirange</function> ( <type>anyrange</type> )
21651 <returnvalue>anymultirange</returnvalue>
21652 </para>
21653 <para>
21654 Returns a multirange containing just the given range.
21655 </para>
21656 <para>
21657 <literal>multirange('[1,2)'::int4range)</literal>
21658 <returnvalue>{[1,2)}</returnvalue>
21659 </para></entry>
21660 </row>
21662 <row>
21663 <entry role="func_table_entry"><para role="func_signature">
21664 <indexterm>
21665 <primary>unnest</primary>
21666 <secondary>for multirange</secondary>
21667 </indexterm>
21668 <function>unnest</function> ( <type>anymultirange</type> )
21669 <returnvalue>setof anyrange</returnvalue>
21670 </para>
21671 <para>
21672 Expands a multirange into a set of ranges in ascending order.
21673 </para>
21674 <para>
21675 <literal>unnest('{[1,2), [3,4)}'::int4multirange)</literal>
21676 <returnvalue></returnvalue>
21677 <programlisting>
21678 [1,2)
21679 [3,4)
21680 </programlisting>
21681 </para></entry>
21682 </row>
21683 </tbody>
21684 </tgroup>
21685 </table>
21687 <para>
21688 The <function>lower_inc</function>, <function>upper_inc</function>,
21689 <function>lower_inf</function>, and <function>upper_inf</function>
21690 functions all return false for an empty range or multirange.
21691 </para>
21692 </sect1>
21694 <sect1 id="functions-aggregate">
21695 <title>Aggregate Functions</title>
21697 <indexterm zone="functions-aggregate">
21698 <primary>aggregate function</primary>
21699 <secondary>built-in</secondary>
21700 </indexterm>
21702 <para>
21703 <firstterm>Aggregate functions</firstterm> compute a single result
21704 from a set of input values. The built-in general-purpose aggregate
21705 functions are listed in <xref linkend="functions-aggregate-table"/>
21706 while statistical aggregates are in <xref
21707 linkend="functions-aggregate-statistics-table"/>.
21708 The built-in within-group ordered-set aggregate functions
21709 are listed in <xref linkend="functions-orderedset-table"/>
21710 while the built-in within-group hypothetical-set ones are in <xref
21711 linkend="functions-hypothetical-table"/>. Grouping operations,
21712 which are closely related to aggregate functions, are listed in
21713 <xref linkend="functions-grouping-table"/>.
21714 The special syntax considerations for aggregate
21715 functions are explained in <xref linkend="syntax-aggregates"/>.
21716 Consult <xref linkend="tutorial-agg"/> for additional introductory
21717 information.
21718 </para>
21720 <para>
21721 Aggregate functions that support <firstterm>Partial Mode</firstterm>
21722 are eligible to participate in various optimizations, such as parallel
21723 aggregation.
21724 </para>
21726 <para>
21727 While all aggregates below accept an optional
21728 <literal>ORDER BY</literal> clause (as outlined in <xref
21729 linkend="syntax-aggregates"/>), the clause has only been added to
21730 aggregates whose output is affected by ordering.
21731 </para>
21733 <table id="functions-aggregate-table">
21734 <title>General-Purpose Aggregate Functions</title>
21735 <tgroup cols="2">
21736 <colspec colname="col1" colwidth="10*"/>
21737 <colspec colname="col2" colwidth="1*"/>
21738 <thead>
21739 <row>
21740 <entry role="func_table_entry"><para role="func_signature">
21741 Function
21742 </para>
21743 <para>
21744 Description
21745 </para></entry>
21746 <entry>Partial Mode</entry>
21747 </row>
21748 </thead>
21750 <tbody>
21751 <row>
21752 <entry role="func_table_entry"><para role="func_signature">
21753 <indexterm>
21754 <primary>any_value</primary>
21755 </indexterm>
21756 <function>any_value</function> ( <type>anyelement</type> )
21757 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
21758 </para>
21759 <para>
21760 Returns an arbitrary value from the non-null input values.
21761 </para></entry>
21762 <entry>Yes</entry>
21763 </row>
21765 <row>
21766 <entry role="func_table_entry"><para role="func_signature">
21767 <indexterm>
21768 <primary>array_agg</primary>
21769 </indexterm>
21770 <function>array_agg</function> ( <type>anynonarray</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
21771 <returnvalue>anyarray</returnvalue>
21772 </para>
21773 <para>
21774 Collects all the input values, including nulls, into an array.
21775 </para></entry>
21776 <entry>Yes</entry>
21777 </row>
21779 <row>
21780 <entry role="func_table_entry"><para role="func_signature">
21781 <function>array_agg</function> ( <type>anyarray</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
21782 <returnvalue>anyarray</returnvalue>
21783 </para>
21784 <para>
21785 Concatenates all the input arrays into an array of one higher
21786 dimension. (The inputs must all have the same dimensionality, and
21787 cannot be empty or null.)
21788 </para></entry>
21789 <entry>Yes</entry>
21790 </row>
21792 <row>
21793 <entry role="func_table_entry"><para role="func_signature">
21794 <indexterm>
21795 <primary>average</primary>
21796 </indexterm>
21797 <indexterm>
21798 <primary>avg</primary>
21799 </indexterm>
21800 <function>avg</function> ( <type>smallint</type> )
21801 <returnvalue>numeric</returnvalue>
21802 </para>
21803 <para role="func_signature">
21804 <function>avg</function> ( <type>integer</type> )
21805 <returnvalue>numeric</returnvalue>
21806 </para>
21807 <para role="func_signature">
21808 <function>avg</function> ( <type>bigint</type> )
21809 <returnvalue>numeric</returnvalue>
21810 </para>
21811 <para role="func_signature">
21812 <function>avg</function> ( <type>numeric</type> )
21813 <returnvalue>numeric</returnvalue>
21814 </para>
21815 <para role="func_signature">
21816 <function>avg</function> ( <type>real</type> )
21817 <returnvalue>double precision</returnvalue>
21818 </para>
21819 <para role="func_signature">
21820 <function>avg</function> ( <type>double precision</type> )
21821 <returnvalue>double precision</returnvalue>
21822 </para>
21823 <para role="func_signature">
21824 <function>avg</function> ( <type>interval</type> )
21825 <returnvalue>interval</returnvalue>
21826 </para>
21827 <para>
21828 Computes the average (arithmetic mean) of all the non-null input
21829 values.
21830 </para></entry>
21831 <entry>Yes</entry>
21832 </row>
21834 <row>
21835 <entry role="func_table_entry"><para role="func_signature">
21836 <indexterm>
21837 <primary>bit_and</primary>
21838 </indexterm>
21839 <function>bit_and</function> ( <type>smallint</type> )
21840 <returnvalue>smallint</returnvalue>
21841 </para>
21842 <para role="func_signature">
21843 <function>bit_and</function> ( <type>integer</type> )
21844 <returnvalue>integer</returnvalue>
21845 </para>
21846 <para role="func_signature">
21847 <function>bit_and</function> ( <type>bigint</type> )
21848 <returnvalue>bigint</returnvalue>
21849 </para>
21850 <para role="func_signature">
21851 <function>bit_and</function> ( <type>bit</type> )
21852 <returnvalue>bit</returnvalue>
21853 </para>
21854 <para>
21855 Computes the bitwise AND of all non-null input values.
21856 </para></entry>
21857 <entry>Yes</entry>
21858 </row>
21860 <row>
21861 <entry role="func_table_entry"><para role="func_signature">
21862 <indexterm>
21863 <primary>bit_or</primary>
21864 </indexterm>
21865 <function>bit_or</function> ( <type>smallint</type> )
21866 <returnvalue>smallint</returnvalue>
21867 </para>
21868 <para role="func_signature">
21869 <function>bit_or</function> ( <type>integer</type> )
21870 <returnvalue>integer</returnvalue>
21871 </para>
21872 <para role="func_signature">
21873 <function>bit_or</function> ( <type>bigint</type> )
21874 <returnvalue>bigint</returnvalue>
21875 </para>
21876 <para role="func_signature">
21877 <function>bit_or</function> ( <type>bit</type> )
21878 <returnvalue>bit</returnvalue>
21879 </para>
21880 <para>
21881 Computes the bitwise OR of all non-null input values.
21882 </para></entry>
21883 <entry>Yes</entry>
21884 </row>
21886 <row>
21887 <entry role="func_table_entry"><para role="func_signature">
21888 <indexterm>
21889 <primary>bit_xor</primary>
21890 </indexterm>
21891 <function>bit_xor</function> ( <type>smallint</type> )
21892 <returnvalue>smallint</returnvalue>
21893 </para>
21894 <para role="func_signature">
21895 <function>bit_xor</function> ( <type>integer</type> )
21896 <returnvalue>integer</returnvalue>
21897 </para>
21898 <para role="func_signature">
21899 <function>bit_xor</function> ( <type>bigint</type> )
21900 <returnvalue>bigint</returnvalue>
21901 </para>
21902 <para role="func_signature">
21903 <function>bit_xor</function> ( <type>bit</type> )
21904 <returnvalue>bit</returnvalue>
21905 </para>
21906 <para>
21907 Computes the bitwise exclusive OR of all non-null input values.
21908 Can be useful as a checksum for an unordered set of values.
21909 </para></entry>
21910 <entry>Yes</entry>
21911 </row>
21913 <row>
21914 <entry role="func_table_entry"><para role="func_signature">
21915 <indexterm>
21916 <primary>bool_and</primary>
21917 </indexterm>
21918 <function>bool_and</function> ( <type>boolean</type> )
21919 <returnvalue>boolean</returnvalue>
21920 </para>
21921 <para>
21922 Returns true if all non-null input values are true, otherwise false.
21923 </para></entry>
21924 <entry>Yes</entry>
21925 </row>
21927 <row>
21928 <entry role="func_table_entry"><para role="func_signature">
21929 <indexterm>
21930 <primary>bool_or</primary>
21931 </indexterm>
21932 <function>bool_or</function> ( <type>boolean</type> )
21933 <returnvalue>boolean</returnvalue>
21934 </para>
21935 <para>
21936 Returns true if any non-null input value is true, otherwise false.
21937 </para></entry>
21938 <entry>Yes</entry>
21939 </row>
21941 <row>
21942 <entry role="func_table_entry"><para role="func_signature">
21943 <indexterm>
21944 <primary>count</primary>
21945 </indexterm>
21946 <function>count</function> ( <literal>*</literal> )
21947 <returnvalue>bigint</returnvalue>
21948 </para>
21949 <para>
21950 Computes the number of input rows.
21951 </para></entry>
21952 <entry>Yes</entry>
21953 </row>
21955 <row>
21956 <entry role="func_table_entry"><para role="func_signature">
21957 <function>count</function> ( <type>"any"</type> )
21958 <returnvalue>bigint</returnvalue>
21959 </para>
21960 <para>
21961 Computes the number of input rows in which the input value is not
21962 null.
21963 </para></entry>
21964 <entry>Yes</entry>
21965 </row>
21967 <row>
21968 <entry role="func_table_entry"><para role="func_signature">
21969 <indexterm>
21970 <primary>every</primary>
21971 </indexterm>
21972 <function>every</function> ( <type>boolean</type> )
21973 <returnvalue>boolean</returnvalue>
21974 </para>
21975 <para>
21976 This is the SQL standard's equivalent to <function>bool_and</function>.
21977 </para></entry>
21978 <entry>Yes</entry>
21979 </row>
21981 <row>
21982 <entry role="func_table_entry"><para role="func_signature">
21983 <indexterm>
21984 <primary>json_agg</primary>
21985 </indexterm>
21986 <function>json_agg</function> ( <type>anyelement</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
21987 <returnvalue>json</returnvalue>
21988 </para>
21989 <para role="func_signature">
21990 <indexterm>
21991 <primary>jsonb_agg</primary>
21992 </indexterm>
21993 <function>jsonb_agg</function> ( <type>anyelement</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
21994 <returnvalue>jsonb</returnvalue>
21995 </para>
21996 <para>
21997 Collects all the input values, including nulls, into a JSON array.
21998 Values are converted to JSON as per <function>to_json</function>
21999 or <function>to_jsonb</function>.
22000 </para></entry>
22001 <entry>No</entry>
22002 </row>
22004 <row>
22005 <entry role="func_table_entry"><para role="func_signature">
22006 <indexterm>
22007 <primary>json_agg_strict</primary>
22008 </indexterm>
22009 <function>json_agg_strict</function> ( <type>anyelement</type> )
22010 <returnvalue>json</returnvalue>
22011 </para>
22012 <para role="func_signature">
22013 <indexterm>
22014 <primary>jsonb_agg_strict</primary>
22015 </indexterm>
22016 <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
22017 <returnvalue>jsonb</returnvalue>
22018 </para>
22019 <para>
22020 Collects all the input values, skipping nulls, into a JSON array.
22021 Values are converted to JSON as per <function>to_json</function>
22022 or <function>to_jsonb</function>.
22023 </para></entry>
22024 <entry>No</entry>
22025 </row>
22027 <row>
22028 <entry role="func_table_entry"><para role="func_signature">
22029 <indexterm><primary>json_arrayagg</primary></indexterm>
22030 <function>json_arrayagg</function> (
22031 <optional> <replaceable>value_expression</replaceable> </optional>
22032 <optional> <literal>ORDER BY</literal> <replaceable>sort_expression</replaceable> </optional>
22033 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
22034 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
22035 </para>
22036 <para>
22037 Behaves in the same way as <function>json_array</function>
22038 but as an aggregate function so it only takes one
22039 <replaceable>value_expression</replaceable> parameter.
22040 If <literal>ABSENT ON NULL</literal> is specified, any NULL
22041 values are omitted.
22042 If <literal>ORDER BY</literal> is specified, the elements will
22043 appear in the array in that order rather than in the input order.
22044 </para>
22045 <para>
22046 <literal>SELECT json_arrayagg(v) FROM (VALUES(2),(1)) t(v)</literal>
22047 <returnvalue>[2, 1]</returnvalue>
22048 </para></entry>
22049 <entry>No</entry>
22050 </row>
22052 <row>
22053 <entry role="func_table_entry"><para role="func_signature">
22054 <indexterm><primary>json_objectagg</primary></indexterm>
22055 <function>json_objectagg</function> (
22056 <optional> { <replaceable>key_expression</replaceable> { <literal>VALUE</literal> | ':' } <replaceable>value_expression</replaceable> } </optional>
22057 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
22058 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
22059 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
22060 </para>
22061 <para>
22062 Behaves like <function>json_object</function><!-- xref -->, but as an
22063 aggregate function, so it only takes one
22064 <replaceable>key_expression</replaceable> and one
22065 <replaceable>value_expression</replaceable> parameter.
22066 </para>
22067 <para>
22068 <literal>SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date + 1)) AS t(k,v)</literal>
22069 <returnvalue>{ "a" : "2022-05-10", "b" : "2022-05-11" }</returnvalue>
22070 </para></entry>
22071 <entry>No</entry>
22072 </row>
22074 <row>
22075 <entry role="func_table_entry"><para role="func_signature">
22076 <indexterm>
22077 <primary>json_object_agg</primary>
22078 </indexterm>
22079 <function>json_object_agg</function> ( <parameter>key</parameter>
22080 <type>"any"</type>, <parameter>value</parameter>
22081 <type>"any"</type>
22082 <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
22083 <returnvalue>json</returnvalue>
22084 </para>
22085 <para role="func_signature">
22086 <indexterm>
22087 <primary>jsonb_object_agg</primary>
22088 </indexterm>
22089 <function>jsonb_object_agg</function> ( <parameter>key</parameter>
22090 <type>"any"</type>, <parameter>value</parameter>
22091 <type>"any"</type>
22092 <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
22093 <returnvalue>jsonb</returnvalue>
22094 </para>
22095 <para>
22096 Collects all the key/value pairs into a JSON object. Key arguments
22097 are coerced to text; value arguments are converted as per
22098 <function>to_json</function> or <function>to_jsonb</function>.
22099 Values can be null, but keys cannot.
22100 </para></entry>
22101 <entry>No</entry>
22102 </row>
22104 <row>
22105 <entry role="func_table_entry"><para role="func_signature">
22106 <indexterm>
22107 <primary>json_object_agg_strict</primary>
22108 </indexterm>
22109 <function>json_object_agg_strict</function> (
22110 <parameter>key</parameter> <type>"any"</type>,
22111 <parameter>value</parameter> <type>"any"</type> )
22112 <returnvalue>json</returnvalue>
22113 </para>
22114 <para role="func_signature">
22115 <indexterm>
22116 <primary>jsonb_object_agg_strict</primary>
22117 </indexterm>
22118 <function>jsonb_object_agg_strict</function> (
22119 <parameter>key</parameter> <type>"any"</type>,
22120 <parameter>value</parameter> <type>"any"</type> )
22121 <returnvalue>jsonb</returnvalue>
22122 </para>
22123 <para>
22124 Collects all the key/value pairs into a JSON object. Key arguments
22125 are coerced to text; value arguments are converted as per
22126 <function>to_json</function> or <function>to_jsonb</function>.
22127 The <parameter>key</parameter> can not be null. If the
22128 <parameter>value</parameter> is null then the entry is skipped,
22129 </para></entry>
22130 <entry>No</entry>
22131 </row>
22133 <row>
22134 <entry role="func_table_entry"><para role="func_signature">
22135 <indexterm>
22136 <primary>json_object_agg_unique</primary>
22137 </indexterm>
22138 <function>json_object_agg_unique</function> (
22139 <parameter>key</parameter> <type>"any"</type>,
22140 <parameter>value</parameter> <type>"any"</type> )
22141 <returnvalue>json</returnvalue>
22142 </para>
22143 <para role="func_signature">
22144 <indexterm>
22145 <primary>jsonb_object_agg_unique</primary>
22146 </indexterm>
22147 <function>jsonb_object_agg_unique</function> (
22148 <parameter>key</parameter> <type>"any"</type>,
22149 <parameter>value</parameter> <type>"any"</type> )
22150 <returnvalue>jsonb</returnvalue>
22151 </para>
22152 <para>
22153 Collects all the key/value pairs into a JSON object. Key arguments
22154 are coerced to text; value arguments are converted as per
22155 <function>to_json</function> or <function>to_jsonb</function>.
22156 Values can be null, but keys cannot.
22157 If there is a duplicate key an error is thrown.
22158 </para></entry>
22159 <entry>No</entry>
22160 </row>
22162 <row>
22163 <entry role="func_table_entry"><para role="func_signature">
22164 <indexterm>
22165 <primary>json_object_agg_unique_strict</primary>
22166 </indexterm>
22167 <function>json_object_agg_unique_strict</function> (
22168 <parameter>key</parameter> <type>"any"</type>,
22169 <parameter>value</parameter> <type>"any"</type> )
22170 <returnvalue>json</returnvalue>
22171 </para>
22172 <para role="func_signature">
22173 <indexterm>
22174 <primary>jsonb_object_agg_unique_strict</primary>
22175 </indexterm>
22176 <function>jsonb_object_agg_unique_strict</function> (
22177 <parameter>key</parameter> <type>"any"</type>,
22178 <parameter>value</parameter> <type>"any"</type> )
22179 <returnvalue>jsonb</returnvalue>
22180 </para>
22181 <para>
22182 Collects all the key/value pairs into a JSON object. Key arguments
22183 are coerced to text; value arguments are converted as per
22184 <function>to_json</function> or <function>to_jsonb</function>.
22185 The <parameter>key</parameter> can not be null. If the
22186 <parameter>value</parameter> is null then the entry is skipped.
22187 If there is a duplicate key an error is thrown.
22188 </para></entry>
22189 <entry>No</entry>
22190 </row>
22192 <row>
22193 <entry role="func_table_entry"><para role="func_signature">
22194 <indexterm>
22195 <primary>max</primary>
22196 </indexterm>
22197 <function>max</function> ( <replaceable>see text</replaceable> )
22198 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
22199 </para>
22200 <para>
22201 Computes the maximum of the non-null input
22202 values. Available for any numeric, string, date/time, or enum type,
22203 as well as <type>bytea</type>, <type>inet</type>, <type>interval</type>,
22204 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
22205 <type>tid</type>, <type>xid8</type>,
22206 and also arrays and composite types containing sortable data types.
22207 </para></entry>
22208 <entry>Yes</entry>
22209 </row>
22211 <row>
22212 <entry role="func_table_entry"><para role="func_signature">
22213 <indexterm>
22214 <primary>min</primary>
22215 </indexterm>
22216 <function>min</function> ( <replaceable>see text</replaceable> )
22217 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
22218 </para>
22219 <para>
22220 Computes the minimum of the non-null input
22221 values. Available for any numeric, string, date/time, or enum type,
22222 as well as <type>bytea</type>, <type>inet</type>, <type>interval</type>,
22223 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
22224 <type>tid</type>, <type>xid8</type>,
22225 and also arrays and composite types containing sortable data types.
22226 </para></entry>
22227 <entry>Yes</entry>
22228 </row>
22230 <row>
22231 <entry role="func_table_entry"><para role="func_signature">
22232 <indexterm>
22233 <primary>range_agg</primary>
22234 </indexterm>
22235 <function>range_agg</function> ( <parameter>value</parameter>
22236 <type>anyrange</type> )
22237 <returnvalue>anymultirange</returnvalue>
22238 </para>
22239 <para role="func_signature">
22240 <function>range_agg</function> ( <parameter>value</parameter>
22241 <type>anymultirange</type> )
22242 <returnvalue>anymultirange</returnvalue>
22243 </para>
22244 <para>
22245 Computes the union of the non-null input values.
22246 </para></entry>
22247 <entry>No</entry>
22248 </row>
22250 <row>
22251 <entry role="func_table_entry"><para role="func_signature">
22252 <indexterm>
22253 <primary>range_intersect_agg</primary>
22254 </indexterm>
22255 <function>range_intersect_agg</function> ( <parameter>value</parameter>
22256 <type>anyrange</type> )
22257 <returnvalue>anyrange</returnvalue>
22258 </para>
22259 <para role="func_signature">
22260 <function>range_intersect_agg</function> ( <parameter>value</parameter>
22261 <type>anymultirange</type> )
22262 <returnvalue>anymultirange</returnvalue>
22263 </para>
22264 <para>
22265 Computes the intersection of the non-null input values.
22266 </para></entry>
22267 <entry>No</entry>
22268 </row>
22270 <row>
22271 <entry role="func_table_entry"><para role="func_signature">
22272 <indexterm>
22273 <primary>string_agg</primary>
22274 </indexterm>
22275 <function>string_agg</function> ( <parameter>value</parameter>
22276 <type>text</type>, <parameter>delimiter</parameter> <type>text</type> )
22277 <returnvalue>text</returnvalue>
22278 </para>
22279 <para role="func_signature">
22280 <function>string_agg</function> ( <parameter>value</parameter>
22281 <type>bytea</type>, <parameter>delimiter</parameter> <type>bytea</type>
22282 <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
22283 <returnvalue>bytea</returnvalue>
22284 </para>
22285 <para>
22286 Concatenates the non-null input values into a string. Each value
22287 after the first is preceded by the
22288 corresponding <parameter>delimiter</parameter> (if it's not null).
22289 </para></entry>
22290 <entry>Yes</entry>
22291 </row>
22293 <row>
22294 <entry role="func_table_entry"><para role="func_signature">
22295 <indexterm>
22296 <primary>sum</primary>
22297 </indexterm>
22298 <function>sum</function> ( <type>smallint</type> )
22299 <returnvalue>bigint</returnvalue>
22300 </para>
22301 <para role="func_signature">
22302 <function>sum</function> ( <type>integer</type> )
22303 <returnvalue>bigint</returnvalue>
22304 </para>
22305 <para role="func_signature">
22306 <function>sum</function> ( <type>bigint</type> )
22307 <returnvalue>numeric</returnvalue>
22308 </para>
22309 <para role="func_signature">
22310 <function>sum</function> ( <type>numeric</type> )
22311 <returnvalue>numeric</returnvalue>
22312 </para>
22313 <para role="func_signature">
22314 <function>sum</function> ( <type>real</type> )
22315 <returnvalue>real</returnvalue>
22316 </para>
22317 <para role="func_signature">
22318 <function>sum</function> ( <type>double precision</type> )
22319 <returnvalue>double precision</returnvalue>
22320 </para>
22321 <para role="func_signature">
22322 <function>sum</function> ( <type>interval</type> )
22323 <returnvalue>interval</returnvalue>
22324 </para>
22325 <para role="func_signature">
22326 <function>sum</function> ( <type>money</type> )
22327 <returnvalue>money</returnvalue>
22328 </para>
22329 <para>
22330 Computes the sum of the non-null input values.
22331 </para></entry>
22332 <entry>Yes</entry>
22333 </row>
22335 <row>
22336 <entry role="func_table_entry"><para role="func_signature">
22337 <indexterm>
22338 <primary>xmlagg</primary>
22339 </indexterm>
22340 <function>xmlagg</function> ( <type>xml</type> <literal>ORDER BY</literal> <literal>input_sort_columns</literal> )
22341 <returnvalue>xml</returnvalue>
22342 </para>
22343 <para>
22344 Concatenates the non-null XML input values (see
22345 <xref linkend="functions-xml-xmlagg"/>).
22346 </para></entry>
22347 <entry>No</entry>
22348 </row>
22349 </tbody>
22350 </tgroup>
22351 </table>
22353 <para>
22354 It should be noted that except for <function>count</function>,
22355 these functions return a null value when no rows are selected. In
22356 particular, <function>sum</function> of no rows returns null, not
22357 zero as one might expect, and <function>array_agg</function>
22358 returns null rather than an empty array when there are no input
22359 rows. The <function>coalesce</function> function can be used to
22360 substitute zero or an empty array for null when necessary.
22361 </para>
22363 <para>
22364 The aggregate functions <function>array_agg</function>,
22365 <function>json_agg</function>, <function>jsonb_agg</function>,
22366 <function>json_agg_strict</function>, <function>jsonb_agg_strict</function>,
22367 <function>json_object_agg</function>, <function>jsonb_object_agg</function>,
22368 <function>json_object_agg_strict</function>, <function>jsonb_object_agg_strict</function>,
22369 <function>json_object_agg_unique</function>, <function>jsonb_object_agg_unique</function>,
22370 <function>json_object_agg_unique_strict</function>,
22371 <function>jsonb_object_agg_unique_strict</function>,
22372 <function>string_agg</function>,
22373 and <function>xmlagg</function>, as well as similar user-defined
22374 aggregate functions, produce meaningfully different result values
22375 depending on the order of the input values. This ordering is
22376 unspecified by default, but can be controlled by writing an
22377 <literal>ORDER BY</literal> clause within the aggregate call, as shown in
22378 <xref linkend="syntax-aggregates"/>.
22379 Alternatively, supplying the input values from a sorted subquery
22380 will usually work. For example:
22382 <screen><![CDATA[
22383 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
22384 ]]></screen>
22386 Beware that this approach can fail if the outer query level contains
22387 additional processing, such as a join, because that might cause the
22388 subquery's output to be reordered before the aggregate is computed.
22389 </para>
22391 <note>
22392 <indexterm>
22393 <primary>ANY</primary>
22394 </indexterm>
22395 <indexterm>
22396 <primary>SOME</primary>
22397 </indexterm>
22398 <para>
22399 The boolean aggregates <function>bool_and</function> and
22400 <function>bool_or</function> correspond to the standard SQL aggregates
22401 <function>every</function> and <function>any</function> or
22402 <function>some</function>.
22403 <productname>PostgreSQL</productname>
22404 supports <function>every</function>, but not <function>any</function>
22405 or <function>some</function>, because there is an ambiguity built into
22406 the standard syntax:
22407 <programlisting>
22408 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
22409 </programlisting>
22410 Here <function>ANY</function> can be considered either as introducing
22411 a subquery, or as being an aggregate function, if the subquery
22412 returns one row with a Boolean value.
22413 Thus the standard name cannot be given to these aggregates.
22414 </para>
22415 </note>
22417 <note>
22418 <para>
22419 Users accustomed to working with other SQL database management
22420 systems might be disappointed by the performance of the
22421 <function>count</function> aggregate when it is applied to the
22422 entire table. A query like:
22423 <programlisting>
22424 SELECT count(*) FROM sometable;
22425 </programlisting>
22426 will require effort proportional to the size of the table:
22427 <productname>PostgreSQL</productname> will need to scan either the
22428 entire table or the entirety of an index that includes all rows in
22429 the table.
22430 </para>
22431 </note>
22433 <para>
22434 <xref linkend="functions-aggregate-statistics-table"/> shows
22435 aggregate functions typically used in statistical analysis.
22436 (These are separated out merely to avoid cluttering the listing
22437 of more-commonly-used aggregates.) Functions shown as
22438 accepting <replaceable>numeric_type</replaceable> are available for all
22439 the types <type>smallint</type>, <type>integer</type>,
22440 <type>bigint</type>, <type>numeric</type>, <type>real</type>,
22441 and <type>double precision</type>.
22442 Where the description mentions
22443 <parameter>N</parameter>, it means the
22444 number of input rows for which all the input expressions are non-null.
22445 In all cases, null is returned if the computation is meaningless,
22446 for example when <parameter>N</parameter> is zero.
22447 </para>
22449 <indexterm>
22450 <primary>statistics</primary>
22451 </indexterm>
22452 <indexterm>
22453 <primary>linear regression</primary>
22454 </indexterm>
22456 <table id="functions-aggregate-statistics-table">
22457 <title>Aggregate Functions for Statistics</title>
22458 <tgroup cols="2">
22459 <colspec colname="col1" colwidth="10*"/>
22460 <colspec colname="col2" colwidth="1*"/>
22461 <thead>
22462 <row>
22463 <entry role="func_table_entry"><para role="func_signature">
22464 Function
22465 </para>
22466 <para>
22467 Description
22468 </para></entry>
22469 <entry>Partial Mode</entry>
22470 </row>
22471 </thead>
22473 <tbody>
22474 <row>
22475 <entry role="func_table_entry"><para role="func_signature">
22476 <indexterm>
22477 <primary>correlation</primary>
22478 </indexterm>
22479 <indexterm>
22480 <primary>corr</primary>
22481 </indexterm>
22482 <function>corr</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22483 <returnvalue>double precision</returnvalue>
22484 </para>
22485 <para>
22486 Computes the correlation coefficient.
22487 </para></entry>
22488 <entry>Yes</entry>
22489 </row>
22491 <row>
22492 <entry role="func_table_entry"><para role="func_signature">
22493 <indexterm>
22494 <primary>covariance</primary>
22495 <secondary>population</secondary>
22496 </indexterm>
22497 <indexterm>
22498 <primary>covar_pop</primary>
22499 </indexterm>
22500 <function>covar_pop</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22501 <returnvalue>double precision</returnvalue>
22502 </para>
22503 <para>
22504 Computes the population covariance.
22505 </para></entry>
22506 <entry>Yes</entry>
22507 </row>
22509 <row>
22510 <entry role="func_table_entry"><para role="func_signature">
22511 <indexterm>
22512 <primary>covariance</primary>
22513 <secondary>sample</secondary>
22514 </indexterm>
22515 <indexterm>
22516 <primary>covar_samp</primary>
22517 </indexterm>
22518 <function>covar_samp</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22519 <returnvalue>double precision</returnvalue>
22520 </para>
22521 <para>
22522 Computes the sample covariance.
22523 </para></entry>
22524 <entry>Yes</entry>
22525 </row>
22527 <row>
22528 <entry role="func_table_entry"><para role="func_signature">
22529 <indexterm>
22530 <primary>regr_avgx</primary>
22531 </indexterm>
22532 <function>regr_avgx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22533 <returnvalue>double precision</returnvalue>
22534 </para>
22535 <para>
22536 Computes the average of the independent variable,
22537 <literal>sum(<parameter>X</parameter>)/<parameter>N</parameter></literal>.
22538 </para></entry>
22539 <entry>Yes</entry>
22540 </row>
22542 <row>
22543 <entry role="func_table_entry"><para role="func_signature">
22544 <indexterm>
22545 <primary>regr_avgy</primary>
22546 </indexterm>
22547 <function>regr_avgy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22548 <returnvalue>double precision</returnvalue>
22549 </para>
22550 <para>
22551 Computes the average of the dependent variable,
22552 <literal>sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
22553 </para></entry>
22554 <entry>Yes</entry>
22555 </row>
22557 <row>
22558 <entry role="func_table_entry"><para role="func_signature">
22559 <indexterm>
22560 <primary>regr_count</primary>
22561 </indexterm>
22562 <function>regr_count</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22563 <returnvalue>bigint</returnvalue>
22564 </para>
22565 <para>
22566 Computes the number of rows in which both inputs are non-null.
22567 </para></entry>
22568 <entry>Yes</entry>
22569 </row>
22571 <row>
22572 <entry role="func_table_entry"><para role="func_signature">
22573 <indexterm>
22574 <primary>regression intercept</primary>
22575 </indexterm>
22576 <indexterm>
22577 <primary>regr_intercept</primary>
22578 </indexterm>
22579 <function>regr_intercept</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22580 <returnvalue>double precision</returnvalue>
22581 </para>
22582 <para>
22583 Computes the y-intercept of the least-squares-fit linear equation
22584 determined by the
22585 (<parameter>X</parameter>, <parameter>Y</parameter>) pairs.
22586 </para></entry>
22587 <entry>Yes</entry>
22588 </row>
22590 <row>
22591 <entry role="func_table_entry"><para role="func_signature">
22592 <indexterm>
22593 <primary>regr_r2</primary>
22594 </indexterm>
22595 <function>regr_r2</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22596 <returnvalue>double precision</returnvalue>
22597 </para>
22598 <para>
22599 Computes the square of the correlation coefficient.
22600 </para></entry>
22601 <entry>Yes</entry>
22602 </row>
22604 <row>
22605 <entry role="func_table_entry"><para role="func_signature">
22606 <indexterm>
22607 <primary>regression slope</primary>
22608 </indexterm>
22609 <indexterm>
22610 <primary>regr_slope</primary>
22611 </indexterm>
22612 <function>regr_slope</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22613 <returnvalue>double precision</returnvalue>
22614 </para>
22615 <para>
22616 Computes the slope of the least-squares-fit linear equation determined
22617 by the (<parameter>X</parameter>, <parameter>Y</parameter>)
22618 pairs.
22619 </para></entry>
22620 <entry>Yes</entry>
22621 </row>
22623 <row>
22624 <entry role="func_table_entry"><para role="func_signature">
22625 <indexterm>
22626 <primary>regr_sxx</primary>
22627 </indexterm>
22628 <function>regr_sxx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22629 <returnvalue>double precision</returnvalue>
22630 </para>
22631 <para>
22632 Computes the <quote>sum of squares</quote> of the independent
22633 variable,
22634 <literal>sum(<parameter>X</parameter>^2) - sum(<parameter>X</parameter>)^2/<parameter>N</parameter></literal>.
22635 </para></entry>
22636 <entry>Yes</entry>
22637 </row>
22639 <row>
22640 <entry role="func_table_entry"><para role="func_signature">
22641 <indexterm>
22642 <primary>regr_sxy</primary>
22643 </indexterm>
22644 <function>regr_sxy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22645 <returnvalue>double precision</returnvalue>
22646 </para>
22647 <para>
22648 Computes the <quote>sum of products</quote> of independent times
22649 dependent variables,
22650 <literal>sum(<parameter>X</parameter>*<parameter>Y</parameter>) - sum(<parameter>X</parameter>) * sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
22651 </para></entry>
22652 <entry>Yes</entry>
22653 </row>
22655 <row>
22656 <entry role="func_table_entry"><para role="func_signature">
22657 <indexterm>
22658 <primary>regr_syy</primary>
22659 </indexterm>
22660 <function>regr_syy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
22661 <returnvalue>double precision</returnvalue>
22662 </para>
22663 <para>
22664 Computes the <quote>sum of squares</quote> of the dependent
22665 variable,
22666 <literal>sum(<parameter>Y</parameter>^2) - sum(<parameter>Y</parameter>)^2/<parameter>N</parameter></literal>.
22667 </para></entry>
22668 <entry>Yes</entry>
22669 </row>
22671 <row>
22672 <entry role="func_table_entry"><para role="func_signature">
22673 <indexterm>
22674 <primary>standard deviation</primary>
22675 </indexterm>
22676 <indexterm>
22677 <primary>stddev</primary>
22678 </indexterm>
22679 <function>stddev</function> ( <replaceable>numeric_type</replaceable> )
22680 <returnvalue></returnvalue> <type>double precision</type>
22681 for <type>real</type> or <type>double precision</type>,
22682 otherwise <type>numeric</type>
22683 </para>
22684 <para>
22685 This is a historical alias for <function>stddev_samp</function>.
22686 </para></entry>
22687 <entry>Yes</entry>
22688 </row>
22690 <row>
22691 <entry role="func_table_entry"><para role="func_signature">
22692 <indexterm>
22693 <primary>standard deviation</primary>
22694 <secondary>population</secondary>
22695 </indexterm>
22696 <indexterm>
22697 <primary>stddev_pop</primary>
22698 </indexterm>
22699 <function>stddev_pop</function> ( <replaceable>numeric_type</replaceable> )
22700 <returnvalue></returnvalue> <type>double precision</type>
22701 for <type>real</type> or <type>double precision</type>,
22702 otherwise <type>numeric</type>
22703 </para>
22704 <para>
22705 Computes the population standard deviation of the input values.
22706 </para></entry>
22707 <entry>Yes</entry>
22708 </row>
22710 <row>
22711 <entry role="func_table_entry"><para role="func_signature">
22712 <indexterm>
22713 <primary>standard deviation</primary>
22714 <secondary>sample</secondary>
22715 </indexterm>
22716 <indexterm>
22717 <primary>stddev_samp</primary>
22718 </indexterm>
22719 <function>stddev_samp</function> ( <replaceable>numeric_type</replaceable> )
22720 <returnvalue></returnvalue> <type>double precision</type>
22721 for <type>real</type> or <type>double precision</type>,
22722 otherwise <type>numeric</type>
22723 </para>
22724 <para>
22725 Computes the sample standard deviation of the input values.
22726 </para></entry>
22727 <entry>Yes</entry>
22728 </row>
22730 <row>
22731 <entry role="func_table_entry"><para role="func_signature">
22732 <indexterm>
22733 <primary>variance</primary>
22734 </indexterm>
22735 <function>variance</function> ( <replaceable>numeric_type</replaceable> )
22736 <returnvalue></returnvalue> <type>double precision</type>
22737 for <type>real</type> or <type>double precision</type>,
22738 otherwise <type>numeric</type>
22739 </para>
22740 <para>
22741 This is a historical alias for <function>var_samp</function>.
22742 </para></entry>
22743 <entry>Yes</entry>
22744 </row>
22746 <row>
22747 <entry role="func_table_entry"><para role="func_signature">
22748 <indexterm>
22749 <primary>variance</primary>
22750 <secondary>population</secondary>
22751 </indexterm>
22752 <indexterm>
22753 <primary>var_pop</primary>
22754 </indexterm>
22755 <function>var_pop</function> ( <replaceable>numeric_type</replaceable> )
22756 <returnvalue></returnvalue> <type>double precision</type>
22757 for <type>real</type> or <type>double precision</type>,
22758 otherwise <type>numeric</type>
22759 </para>
22760 <para>
22761 Computes the population variance of the input values (square of the
22762 population standard deviation).
22763 </para></entry>
22764 <entry>Yes</entry>
22765 </row>
22767 <row>
22768 <entry role="func_table_entry"><para role="func_signature">
22769 <indexterm>
22770 <primary>variance</primary>
22771 <secondary>sample</secondary>
22772 </indexterm>
22773 <indexterm>
22774 <primary>var_samp</primary>
22775 </indexterm>
22776 <function>var_samp</function> ( <replaceable>numeric_type</replaceable> )
22777 <returnvalue></returnvalue> <type>double precision</type>
22778 for <type>real</type> or <type>double precision</type>,
22779 otherwise <type>numeric</type>
22780 </para>
22781 <para>
22782 Computes the sample variance of the input values (square of the sample
22783 standard deviation).
22784 </para></entry>
22785 <entry>Yes</entry>
22786 </row>
22787 </tbody>
22788 </tgroup>
22789 </table>
22791 <para>
22792 <xref linkend="functions-orderedset-table"/> shows some
22793 aggregate functions that use the <firstterm>ordered-set aggregate</firstterm>
22794 syntax. These functions are sometimes referred to as <quote>inverse
22795 distribution</quote> functions. Their aggregated input is introduced by
22796 <literal>ORDER BY</literal>, and they may also take a <firstterm>direct
22797 argument</firstterm> that is not aggregated, but is computed only once.
22798 All these functions ignore null values in their aggregated input.
22799 For those that take a <parameter>fraction</parameter> parameter, the
22800 fraction value must be between 0 and 1; an error is thrown if not.
22801 However, a null <parameter>fraction</parameter> value simply produces a
22802 null result.
22803 </para>
22805 <indexterm>
22806 <primary>ordered-set aggregate</primary>
22807 <secondary>built-in</secondary>
22808 </indexterm>
22809 <indexterm>
22810 <primary>inverse distribution</primary>
22811 </indexterm>
22813 <table id="functions-orderedset-table">
22814 <title>Ordered-Set Aggregate Functions</title>
22815 <tgroup cols="2">
22816 <colspec colname="col1" colwidth="10*"/>
22817 <colspec colname="col2" colwidth="1*"/>
22818 <thead>
22819 <row>
22820 <entry role="func_table_entry"><para role="func_signature">
22821 Function
22822 </para>
22823 <para>
22824 Description
22825 </para></entry>
22826 <entry>Partial Mode</entry>
22827 </row>
22828 </thead>
22830 <tbody>
22831 <row>
22832 <entry role="func_table_entry"><para role="func_signature">
22833 <indexterm>
22834 <primary>mode</primary>
22835 <secondary>statistical</secondary>
22836 </indexterm>
22837 <function>mode</function> () <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
22838 <returnvalue>anyelement</returnvalue>
22839 </para>
22840 <para>
22841 Computes the <firstterm>mode</firstterm>, the most frequent
22842 value of the aggregated argument (arbitrarily choosing the first one
22843 if there are multiple equally-frequent values). The aggregated
22844 argument must be of a sortable type.
22845 </para></entry>
22846 <entry>No</entry>
22847 </row>
22849 <row>
22850 <entry role="func_table_entry"><para role="func_signature">
22851 <indexterm>
22852 <primary>percentile</primary>
22853 <secondary>continuous</secondary>
22854 </indexterm>
22855 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
22856 <returnvalue>double precision</returnvalue>
22857 </para>
22858 <para role="func_signature">
22859 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
22860 <returnvalue>interval</returnvalue>
22861 </para>
22862 <para>
22863 Computes the <firstterm>continuous percentile</firstterm>, a value
22864 corresponding to the specified <parameter>fraction</parameter>
22865 within the ordered set of aggregated argument values. This will
22866 interpolate between adjacent input items if needed.
22867 </para></entry>
22868 <entry>No</entry>
22869 </row>
22871 <row>
22872 <entry role="func_table_entry"><para role="func_signature">
22873 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
22874 <returnvalue>double precision[]</returnvalue>
22875 </para>
22876 <para role="func_signature">
22877 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
22878 <returnvalue>interval[]</returnvalue>
22879 </para>
22880 <para>
22881 Computes multiple continuous percentiles. The result is an array of
22882 the same dimensions as the <parameter>fractions</parameter>
22883 parameter, with each non-null element replaced by the (possibly
22884 interpolated) value corresponding to that percentile.
22885 </para></entry>
22886 <entry>No</entry>
22887 </row>
22889 <row>
22890 <entry role="func_table_entry"><para role="func_signature">
22891 <indexterm>
22892 <primary>percentile</primary>
22893 <secondary>discrete</secondary>
22894 </indexterm>
22895 <function>percentile_disc</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
22896 <returnvalue>anyelement</returnvalue>
22897 </para>
22898 <para>
22899 Computes the <firstterm>discrete percentile</firstterm>, the first
22900 value within the ordered set of aggregated argument values whose
22901 position in the ordering equals or exceeds the
22902 specified <parameter>fraction</parameter>. The aggregated
22903 argument must be of a sortable type.
22904 </para></entry>
22905 <entry>No</entry>
22906 </row>
22908 <row>
22909 <entry role="func_table_entry"><para role="func_signature">
22910 <function>percentile_disc</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
22911 <returnvalue>anyarray</returnvalue>
22912 </para>
22913 <para>
22914 Computes multiple discrete percentiles. The result is an array of the
22915 same dimensions as the <parameter>fractions</parameter> parameter,
22916 with each non-null element replaced by the input value corresponding
22917 to that percentile.
22918 The aggregated argument must be of a sortable type.
22919 </para></entry>
22920 <entry>No</entry>
22921 </row>
22922 </tbody>
22923 </tgroup>
22924 </table>
22926 <indexterm>
22927 <primary>hypothetical-set aggregate</primary>
22928 <secondary>built-in</secondary>
22929 </indexterm>
22931 <para>
22932 Each of the <quote>hypothetical-set</quote> aggregates listed in
22933 <xref linkend="functions-hypothetical-table"/> is associated with a
22934 window function of the same name defined in
22935 <xref linkend="functions-window"/>. In each case, the aggregate's result
22936 is the value that the associated window function would have
22937 returned for the <quote>hypothetical</quote> row constructed from
22938 <replaceable>args</replaceable>, if such a row had been added to the sorted
22939 group of rows represented by the <replaceable>sorted_args</replaceable>.
22940 For each of these functions, the list of direct arguments
22941 given in <replaceable>args</replaceable> must match the number and types of
22942 the aggregated arguments given in <replaceable>sorted_args</replaceable>.
22943 Unlike most built-in aggregates, these aggregates are not strict, that is
22944 they do not drop input rows containing nulls. Null values sort according
22945 to the rule specified in the <literal>ORDER BY</literal> clause.
22946 </para>
22948 <table id="functions-hypothetical-table">
22949 <title>Hypothetical-Set Aggregate Functions</title>
22950 <tgroup cols="2">
22951 <colspec colname="col1" colwidth="10*"/>
22952 <colspec colname="col2" colwidth="1*"/>
22953 <thead>
22954 <row>
22955 <entry role="func_table_entry"><para role="func_signature">
22956 Function
22957 </para>
22958 <para>
22959 Description
22960 </para></entry>
22961 <entry>Partial Mode</entry>
22962 </row>
22963 </thead>
22965 <tbody>
22966 <row>
22967 <entry role="func_table_entry"><para role="func_signature">
22968 <indexterm>
22969 <primary>rank</primary>
22970 <secondary>hypothetical</secondary>
22971 </indexterm>
22972 <function>rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
22973 <returnvalue>bigint</returnvalue>
22974 </para>
22975 <para>
22976 Computes the rank of the hypothetical row, with gaps; that is, the row
22977 number of the first row in its peer group.
22978 </para></entry>
22979 <entry>No</entry>
22980 </row>
22982 <row>
22983 <entry role="func_table_entry"><para role="func_signature">
22984 <indexterm>
22985 <primary>dense_rank</primary>
22986 <secondary>hypothetical</secondary>
22987 </indexterm>
22988 <function>dense_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
22989 <returnvalue>bigint</returnvalue>
22990 </para>
22991 <para>
22992 Computes the rank of the hypothetical row, without gaps; this function
22993 effectively counts peer groups.
22994 </para></entry>
22995 <entry>No</entry>
22996 </row>
22998 <row>
22999 <entry role="func_table_entry"><para role="func_signature">
23000 <indexterm>
23001 <primary>percent_rank</primary>
23002 <secondary>hypothetical</secondary>
23003 </indexterm>
23004 <function>percent_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
23005 <returnvalue>double precision</returnvalue>
23006 </para>
23007 <para>
23008 Computes the relative rank of the hypothetical row, that is
23009 (<function>rank</function> - 1) / (total rows - 1).
23010 The value thus ranges from 0 to 1 inclusive.
23011 </para></entry>
23012 <entry>No</entry>
23013 </row>
23015 <row>
23016 <entry role="func_table_entry"><para role="func_signature">
23017 <indexterm>
23018 <primary>cume_dist</primary>
23019 <secondary>hypothetical</secondary>
23020 </indexterm>
23021 <function>cume_dist</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
23022 <returnvalue>double precision</returnvalue>
23023 </para>
23024 <para>
23025 Computes the cumulative distribution, that is (number of rows
23026 preceding or peers with hypothetical row) / (total rows). The value
23027 thus ranges from 1/<parameter>N</parameter> to 1.
23028 </para></entry>
23029 <entry>No</entry>
23030 </row>
23031 </tbody>
23032 </tgroup>
23033 </table>
23035 <table id="functions-grouping-table">
23036 <title>Grouping Operations</title>
23037 <tgroup cols="1">
23038 <thead>
23039 <row>
23040 <entry role="func_table_entry"><para role="func_signature">
23041 Function
23042 </para>
23043 <para>
23044 Description
23045 </para></entry>
23046 </row>
23047 </thead>
23049 <tbody>
23050 <row>
23051 <entry role="func_table_entry"><para role="func_signature">
23052 <indexterm>
23053 <primary>GROUPING</primary>
23054 </indexterm>
23055 <function>GROUPING</function> ( <replaceable>group_by_expression(s)</replaceable> )
23056 <returnvalue>integer</returnvalue>
23057 </para>
23058 <para>
23059 Returns a bit mask indicating which <literal>GROUP BY</literal>
23060 expressions are not included in the current grouping set.
23061 Bits are assigned with the rightmost argument corresponding to the
23062 least-significant bit; each bit is 0 if the corresponding expression
23063 is included in the grouping criteria of the grouping set generating
23064 the current result row, and 1 if it is not included.
23065 </para></entry>
23066 </row>
23067 </tbody>
23068 </tgroup>
23069 </table>
23071 <para>
23072 The grouping operations shown in
23073 <xref linkend="functions-grouping-table"/> are used in conjunction with
23074 grouping sets (see <xref linkend="queries-grouping-sets"/>) to distinguish
23075 result rows. The arguments to the <literal>GROUPING</literal> function
23076 are not actually evaluated, but they must exactly match expressions given
23077 in the <literal>GROUP BY</literal> clause of the associated query level.
23078 For example:
23079 <screen>
23080 <prompt>=&gt;</prompt> <userinput>SELECT * FROM items_sold;</userinput>
23081 make | model | sales
23082 -------+-------+-------
23083 Foo | GT | 10
23084 Foo | Tour | 20
23085 Bar | City | 15
23086 Bar | Sport | 5
23087 (4 rows)
23089 <prompt>=&gt;</prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</userinput>
23090 make | model | grouping | sum
23091 -------+-------+----------+-----
23092 Foo | GT | 0 | 10
23093 Foo | Tour | 0 | 20
23094 Bar | City | 0 | 15
23095 Bar | Sport | 0 | 5
23096 Foo | | 1 | 30
23097 Bar | | 1 | 20
23098 | | 3 | 50
23099 (7 rows)
23100 </screen>
23101 Here, the <literal>grouping</literal> value <literal>0</literal> in the
23102 first four rows shows that those have been grouped normally, over both the
23103 grouping columns. The value <literal>1</literal> indicates
23104 that <literal>model</literal> was not grouped by in the next-to-last two
23105 rows, and the value <literal>3</literal> indicates that
23106 neither <literal>make</literal> nor <literal>model</literal> was grouped
23107 by in the last row (which therefore is an aggregate over all the input
23108 rows).
23109 </para>
23111 </sect1>
23113 <sect1 id="functions-window">
23114 <title>Window Functions</title>
23116 <indexterm zone="functions-window">
23117 <primary>window function</primary>
23118 <secondary>built-in</secondary>
23119 </indexterm>
23121 <para>
23122 <firstterm>Window functions</firstterm> provide the ability to perform
23123 calculations across sets of rows that are related to the current query
23124 row. See <xref linkend="tutorial-window"/> for an introduction to this
23125 feature, and <xref linkend="syntax-window-functions"/> for syntax
23126 details.
23127 </para>
23129 <para>
23130 The built-in window functions are listed in
23131 <xref linkend="functions-window-table"/>. Note that these functions
23132 <emphasis>must</emphasis> be invoked using window function syntax, i.e., an
23133 <literal>OVER</literal> clause is required.
23134 </para>
23136 <para>
23137 In addition to these functions, any built-in or user-defined
23138 ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates)
23139 can be used as a window function; see
23140 <xref linkend="functions-aggregate"/> for a list of the built-in aggregates.
23141 Aggregate functions act as window functions only when an <literal>OVER</literal>
23142 clause follows the call; otherwise they act as plain aggregates
23143 and return a single row for the entire set.
23144 </para>
23146 <table id="functions-window-table">
23147 <title>General-Purpose Window Functions</title>
23148 <tgroup cols="1">
23149 <thead>
23150 <row>
23151 <entry role="func_table_entry"><para role="func_signature">
23152 Function
23153 </para>
23154 <para>
23155 Description
23156 </para></entry>
23157 </row>
23158 </thead>
23160 <tbody>
23161 <row>
23162 <entry role="func_table_entry"><para role="func_signature">
23163 <indexterm>
23164 <primary>row_number</primary>
23165 </indexterm>
23166 <function>row_number</function> ()
23167 <returnvalue>bigint</returnvalue>
23168 </para>
23169 <para>
23170 Returns the number of the current row within its partition, counting
23171 from 1.
23172 </para></entry>
23173 </row>
23175 <row>
23176 <entry role="func_table_entry"><para role="func_signature">
23177 <indexterm>
23178 <primary>rank</primary>
23179 </indexterm>
23180 <function>rank</function> ()
23181 <returnvalue>bigint</returnvalue>
23182 </para>
23183 <para>
23184 Returns the rank of the current row, with gaps; that is,
23185 the <function>row_number</function> of the first row in its peer
23186 group.
23187 </para></entry>
23188 </row>
23190 <row>
23191 <entry role="func_table_entry"><para role="func_signature">
23192 <indexterm>
23193 <primary>dense_rank</primary>
23194 </indexterm>
23195 <function>dense_rank</function> ()
23196 <returnvalue>bigint</returnvalue>
23197 </para>
23198 <para>
23199 Returns the rank of the current row, without gaps; this function
23200 effectively counts peer groups.
23201 </para></entry>
23202 </row>
23204 <row>
23205 <entry role="func_table_entry"><para role="func_signature">
23206 <indexterm>
23207 <primary>percent_rank</primary>
23208 </indexterm>
23209 <function>percent_rank</function> ()
23210 <returnvalue>double precision</returnvalue>
23211 </para>
23212 <para>
23213 Returns the relative rank of the current row, that is
23214 (<function>rank</function> - 1) / (total partition rows - 1).
23215 The value thus ranges from 0 to 1 inclusive.
23216 </para></entry>
23217 </row>
23219 <row>
23220 <entry role="func_table_entry"><para role="func_signature">
23221 <indexterm>
23222 <primary>cume_dist</primary>
23223 </indexterm>
23224 <function>cume_dist</function> ()
23225 <returnvalue>double precision</returnvalue>
23226 </para>
23227 <para>
23228 Returns the cumulative distribution, that is (number of partition rows
23229 preceding or peers with current row) / (total partition rows).
23230 The value thus ranges from 1/<parameter>N</parameter> to 1.
23231 </para></entry>
23232 </row>
23234 <row>
23235 <entry role="func_table_entry"><para role="func_signature">
23236 <indexterm>
23237 <primary>ntile</primary>
23238 </indexterm>
23239 <function>ntile</function> ( <parameter>num_buckets</parameter> <type>integer</type> )
23240 <returnvalue>integer</returnvalue>
23241 </para>
23242 <para>
23243 Returns an integer ranging from 1 to the argument value, dividing the
23244 partition as equally as possible.
23245 </para></entry>
23246 </row>
23248 <row>
23249 <entry role="func_table_entry"><para role="func_signature">
23250 <indexterm>
23251 <primary>lag</primary>
23252 </indexterm>
23253 <function>lag</function> ( <parameter>value</parameter> <type>anycompatible</type>
23254 <optional>, <parameter>offset</parameter> <type>integer</type>
23255 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
23256 <returnvalue>anycompatible</returnvalue>
23257 </para>
23258 <para>
23259 Returns <parameter>value</parameter> evaluated at
23260 the row that is <parameter>offset</parameter>
23261 rows before the current row within the partition; if there is no such
23262 row, instead returns <parameter>default</parameter>
23263 (which must be of a type compatible with
23264 <parameter>value</parameter>).
23265 Both <parameter>offset</parameter> and
23266 <parameter>default</parameter> are evaluated
23267 with respect to the current row. If omitted,
23268 <parameter>offset</parameter> defaults to 1 and
23269 <parameter>default</parameter> to <literal>NULL</literal>.
23270 </para></entry>
23271 </row>
23273 <row>
23274 <entry role="func_table_entry"><para role="func_signature">
23275 <indexterm>
23276 <primary>lead</primary>
23277 </indexterm>
23278 <function>lead</function> ( <parameter>value</parameter> <type>anycompatible</type>
23279 <optional>, <parameter>offset</parameter> <type>integer</type>
23280 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
23281 <returnvalue>anycompatible</returnvalue>
23282 </para>
23283 <para>
23284 Returns <parameter>value</parameter> evaluated at
23285 the row that is <parameter>offset</parameter>
23286 rows after the current row within the partition; if there is no such
23287 row, instead returns <parameter>default</parameter>
23288 (which must be of a type compatible with
23289 <parameter>value</parameter>).
23290 Both <parameter>offset</parameter> and
23291 <parameter>default</parameter> are evaluated
23292 with respect to the current row. If omitted,
23293 <parameter>offset</parameter> defaults to 1 and
23294 <parameter>default</parameter> to <literal>NULL</literal>.
23295 </para></entry>
23296 </row>
23298 <row>
23299 <entry role="func_table_entry"><para role="func_signature">
23300 <indexterm>
23301 <primary>first_value</primary>
23302 </indexterm>
23303 <function>first_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
23304 <returnvalue>anyelement</returnvalue>
23305 </para>
23306 <para>
23307 Returns <parameter>value</parameter> evaluated
23308 at the row that is the first row of the window frame.
23309 </para></entry>
23310 </row>
23312 <row>
23313 <entry role="func_table_entry"><para role="func_signature">
23314 <indexterm>
23315 <primary>last_value</primary>
23316 </indexterm>
23317 <function>last_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
23318 <returnvalue>anyelement</returnvalue>
23319 </para>
23320 <para>
23321 Returns <parameter>value</parameter> evaluated
23322 at the row that is the last row of the window frame.
23323 </para></entry>
23324 </row>
23326 <row>
23327 <entry role="func_table_entry"><para role="func_signature">
23328 <indexterm>
23329 <primary>nth_value</primary>
23330 </indexterm>
23331 <function>nth_value</function> ( <parameter>value</parameter> <type>anyelement</type>, <parameter>n</parameter> <type>integer</type> )
23332 <returnvalue>anyelement</returnvalue>
23333 </para>
23334 <para>
23335 Returns <parameter>value</parameter> evaluated
23336 at the row that is the <parameter>n</parameter>'th
23337 row of the window frame (counting from 1);
23338 returns <literal>NULL</literal> if there is no such row.
23339 </para></entry>
23340 </row>
23341 </tbody>
23342 </tgroup>
23343 </table>
23345 <para>
23346 All of the functions listed in
23347 <xref linkend="functions-window-table"/> depend on the sort ordering
23348 specified by the <literal>ORDER BY</literal> clause of the associated window
23349 definition. Rows that are not distinct when considering only the
23350 <literal>ORDER BY</literal> columns are said to be <firstterm>peers</firstterm>.
23351 The four ranking functions (including <function>cume_dist</function>) are
23352 defined so that they give the same answer for all rows of a peer group.
23353 </para>
23355 <para>
23356 Note that <function>first_value</function>, <function>last_value</function>, and
23357 <function>nth_value</function> consider only the rows within the <quote>window
23358 frame</quote>, which by default contains the rows from the start of the
23359 partition through the last peer of the current row. This is
23360 likely to give unhelpful results for <function>last_value</function> and
23361 sometimes also <function>nth_value</function>. You can redefine the frame by
23362 adding a suitable frame specification (<literal>RANGE</literal>,
23363 <literal>ROWS</literal> or <literal>GROUPS</literal>) to
23364 the <literal>OVER</literal> clause.
23365 See <xref linkend="syntax-window-functions"/> for more information
23366 about frame specifications.
23367 </para>
23369 <para>
23370 When an aggregate function is used as a window function, it aggregates
23371 over the rows within the current row's window frame.
23372 An aggregate used with <literal>ORDER BY</literal> and the default window frame
23373 definition produces a <quote>running sum</quote> type of behavior, which may or
23374 may not be what's wanted. To obtain
23375 aggregation over the whole partition, omit <literal>ORDER BY</literal> or use
23376 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</literal>.
23377 Other frame specifications can be used to obtain other effects.
23378 </para>
23380 <note>
23381 <para>
23382 The SQL standard defines a <literal>RESPECT NULLS</literal> or
23383 <literal>IGNORE NULLS</literal> option for <function>lead</function>, <function>lag</function>,
23384 <function>first_value</function>, <function>last_value</function>, and
23385 <function>nth_value</function>. This is not implemented in
23386 <productname>PostgreSQL</productname>: the behavior is always the
23387 same as the standard's default, namely <literal>RESPECT NULLS</literal>.
23388 Likewise, the standard's <literal>FROM FIRST</literal> or <literal>FROM LAST</literal>
23389 option for <function>nth_value</function> is not implemented: only the
23390 default <literal>FROM FIRST</literal> behavior is supported. (You can achieve
23391 the result of <literal>FROM LAST</literal> by reversing the <literal>ORDER BY</literal>
23392 ordering.)
23393 </para>
23394 </note>
23396 </sect1>
23398 <sect1 id="functions-merge-support">
23399 <title>Merge Support Functions</title>
23401 <indexterm>
23402 <primary>MERGE</primary>
23403 <secondary>RETURNING</secondary>
23404 </indexterm>
23406 <para>
23407 <productname>PostgreSQL</productname> includes one merge support function
23408 that may be used in the <literal>RETURNING</literal> list of a
23409 <xref linkend="sql-merge"/> command to identify the action taken for each
23410 row; see <xref linkend="functions-merge-support-table"/>.
23411 </para>
23413 <table id="functions-merge-support-table">
23414 <title>Merge Support Functions</title>
23416 <tgroup cols="1">
23417 <thead>
23418 <row>
23419 <entry role="func_table_entry"><para role="func_signature">
23420 Function
23421 </para>
23422 <para>
23423 Description
23424 </para></entry>
23425 </row>
23426 </thead>
23428 <tbody>
23429 <row>
23430 <entry id="merge-action" role="func_table_entry"><para role="func_signature">
23431 <indexterm>
23432 <primary>merge_action</primary>
23433 </indexterm>
23434 <function>merge_action</function> ( )
23435 <returnvalue>text</returnvalue>
23436 </para>
23437 <para>
23438 Returns the merge action command executed for the current row. This
23439 will be <literal>'INSERT'</literal>, <literal>'UPDATE'</literal>, or
23440 <literal>'DELETE'</literal>.
23441 </para></entry>
23442 </row>
23443 </tbody>
23444 </tgroup>
23445 </table>
23447 <para>
23448 Example:
23449 <screen><![CDATA[
23450 MERGE INTO products p
23451 USING stock s ON p.product_id = s.product_id
23452 WHEN MATCHED AND s.quantity > 0 THEN
23453 UPDATE SET in_stock = true, quantity = s.quantity
23454 WHEN MATCHED THEN
23455 UPDATE SET in_stock = false, quantity = 0
23456 WHEN NOT MATCHED THEN
23457 INSERT (product_id, in_stock, quantity)
23458 VALUES (s.product_id, true, s.quantity)
23459 RETURNING merge_action(), p.*;
23461 merge_action | product_id | in_stock | quantity
23462 --------------+------------+----------+----------
23463 UPDATE | 1001 | t | 50
23464 UPDATE | 1002 | f | 0
23465 INSERT | 1003 | t | 10
23466 ]]></screen>
23467 </para>
23469 <para>
23470 Note that this function can only be used in the <literal>RETURNING</literal>
23471 list of a <command>MERGE</command> command. It is an error to use it in any
23472 other part of a query.
23473 </para>
23475 </sect1>
23477 <sect1 id="functions-subquery">
23478 <title>Subquery Expressions</title>
23480 <indexterm>
23481 <primary>EXISTS</primary>
23482 </indexterm>
23484 <indexterm>
23485 <primary>IN</primary>
23486 </indexterm>
23488 <indexterm>
23489 <primary>NOT IN</primary>
23490 </indexterm>
23492 <indexterm>
23493 <primary>ANY</primary>
23494 </indexterm>
23496 <indexterm>
23497 <primary>ALL</primary>
23498 </indexterm>
23500 <indexterm>
23501 <primary>SOME</primary>
23502 </indexterm>
23504 <indexterm>
23505 <primary>subquery</primary>
23506 </indexterm>
23508 <para>
23509 This section describes the <acronym>SQL</acronym>-compliant subquery
23510 expressions available in <productname>PostgreSQL</productname>.
23511 All of the expression forms documented in this section return
23512 Boolean (true/false) results.
23513 </para>
23515 <sect2 id="functions-subquery-exists">
23516 <title><literal>EXISTS</literal></title>
23518 <synopsis>
23519 EXISTS (<replaceable>subquery</replaceable>)
23520 </synopsis>
23522 <para>
23523 The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</command> statement,
23524 or <firstterm>subquery</firstterm>. The
23525 subquery is evaluated to determine whether it returns any rows.
23526 If it returns at least one row, the result of <token>EXISTS</token> is
23527 <quote>true</quote>; if the subquery returns no rows, the result of <token>EXISTS</token>
23528 is <quote>false</quote>.
23529 </para>
23531 <para>
23532 The subquery can refer to variables from the surrounding query,
23533 which will act as constants during any one evaluation of the subquery.
23534 </para>
23536 <para>
23537 The subquery will generally only be executed long enough to determine
23538 whether at least one row is returned, not all the way to completion.
23539 It is unwise to write a subquery that has side effects (such as
23540 calling sequence functions); whether the side effects occur
23541 might be unpredictable.
23542 </para>
23544 <para>
23545 Since the result depends only on whether any rows are returned,
23546 and not on the contents of those rows, the output list of the
23547 subquery is normally unimportant. A common coding convention is
23548 to write all <literal>EXISTS</literal> tests in the form
23549 <literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
23550 this rule however, such as subqueries that use <token>INTERSECT</token>.
23551 </para>
23553 <para>
23554 This simple example is like an inner join on <literal>col2</literal>, but
23555 it produces at most one output row for each <literal>tab1</literal> row,
23556 even if there are several matching <literal>tab2</literal> rows:
23557 <screen>
23558 SELECT col1
23559 FROM tab1
23560 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
23561 </screen>
23562 </para>
23563 </sect2>
23565 <sect2 id="functions-subquery-in">
23566 <title><literal>IN</literal></title>
23568 <synopsis>
23569 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
23570 </synopsis>
23572 <para>
23573 The right-hand side is a parenthesized
23574 subquery, which must return exactly one column. The left-hand expression
23575 is evaluated and compared to each row of the subquery result.
23576 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
23577 The result is <quote>false</quote> if no equal row is found (including the
23578 case where the subquery returns no rows).
23579 </para>
23581 <para>
23582 Note that if the left-hand expression yields null, or if there are
23583 no equal right-hand values and at least one right-hand row yields
23584 null, the result of the <token>IN</token> construct will be null, not false.
23585 This is in accordance with SQL's normal rules for Boolean combinations
23586 of null values.
23587 </para>
23589 <para>
23590 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
23591 be evaluated completely.
23592 </para>
23594 <synopsis>
23595 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
23596 </synopsis>
23598 <para>
23599 The left-hand side of this form of <token>IN</token> is a row constructor,
23600 as described in <xref linkend="sql-syntax-row-constructors"/>.
23601 The right-hand side is a parenthesized
23602 subquery, which must return exactly as many columns as there are
23603 expressions in the left-hand row. The left-hand expressions are
23604 evaluated and compared row-wise to each row of the subquery result.
23605 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
23606 The result is <quote>false</quote> if no equal row is found (including the
23607 case where the subquery returns no rows).
23608 </para>
23610 <para>
23611 As usual, null values in the rows are combined per
23612 the normal rules of SQL Boolean expressions. Two rows are considered
23613 equal if all their corresponding members are non-null and equal; the rows
23614 are unequal if any corresponding members are non-null and unequal;
23615 otherwise the result of that row comparison is unknown (null).
23616 If all the per-row results are either unequal or null, with at least one
23617 null, then the result of <token>IN</token> is null.
23618 </para>
23619 </sect2>
23621 <sect2 id="functions-subquery-notin">
23622 <title><literal>NOT IN</literal></title>
23624 <synopsis>
23625 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
23626 </synopsis>
23628 <para>
23629 The right-hand side is a parenthesized
23630 subquery, which must return exactly one column. The left-hand expression
23631 is evaluated and compared to each row of the subquery result.
23632 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
23633 are found (including the case where the subquery returns no rows).
23634 The result is <quote>false</quote> if any equal row is found.
23635 </para>
23637 <para>
23638 Note that if the left-hand expression yields null, or if there are
23639 no equal right-hand values and at least one right-hand row yields
23640 null, the result of the <token>NOT IN</token> construct will be null, not true.
23641 This is in accordance with SQL's normal rules for Boolean combinations
23642 of null values.
23643 </para>
23645 <para>
23646 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
23647 be evaluated completely.
23648 </para>
23650 <synopsis>
23651 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
23652 </synopsis>
23654 <para>
23655 The left-hand side of this form of <token>NOT IN</token> is a row constructor,
23656 as described in <xref linkend="sql-syntax-row-constructors"/>.
23657 The right-hand side is a parenthesized
23658 subquery, which must return exactly as many columns as there are
23659 expressions in the left-hand row. The left-hand expressions are
23660 evaluated and compared row-wise to each row of the subquery result.
23661 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
23662 are found (including the case where the subquery returns no rows).
23663 The result is <quote>false</quote> if any equal row is found.
23664 </para>
23666 <para>
23667 As usual, null values in the rows are combined per
23668 the normal rules of SQL Boolean expressions. Two rows are considered
23669 equal if all their corresponding members are non-null and equal; the rows
23670 are unequal if any corresponding members are non-null and unequal;
23671 otherwise the result of that row comparison is unknown (null).
23672 If all the per-row results are either unequal or null, with at least one
23673 null, then the result of <token>NOT IN</token> is null.
23674 </para>
23675 </sect2>
23677 <sect2 id="functions-subquery-any-some">
23678 <title><literal>ANY</literal>/<literal>SOME</literal></title>
23680 <synopsis>
23681 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
23682 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
23683 </synopsis>
23685 <para>
23686 The right-hand side is a parenthesized
23687 subquery, which must return exactly one column. The left-hand expression
23688 is evaluated and compared to each row of the subquery result using the
23689 given <replaceable>operator</replaceable>, which must yield a Boolean
23690 result.
23691 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
23692 The result is <quote>false</quote> if no true result is found (including the
23693 case where the subquery returns no rows).
23694 </para>
23696 <para>
23697 <token>SOME</token> is a synonym for <token>ANY</token>.
23698 <token>IN</token> is equivalent to <literal>= ANY</literal>.
23699 </para>
23701 <para>
23702 Note that if there are no successes and at least one right-hand row yields
23703 null for the operator's result, the result of the <token>ANY</token> construct
23704 will be null, not false.
23705 This is in accordance with SQL's normal rules for Boolean combinations
23706 of null values.
23707 </para>
23709 <para>
23710 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
23711 be evaluated completely.
23712 </para>
23714 <synopsis>
23715 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
23716 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
23717 </synopsis>
23719 <para>
23720 The left-hand side of this form of <token>ANY</token> is a row constructor,
23721 as described in <xref linkend="sql-syntax-row-constructors"/>.
23722 The right-hand side is a parenthesized
23723 subquery, which must return exactly as many columns as there are
23724 expressions in the left-hand row. The left-hand expressions are
23725 evaluated and compared row-wise to each row of the subquery result,
23726 using the given <replaceable>operator</replaceable>.
23727 The result of <token>ANY</token> is <quote>true</quote> if the comparison
23728 returns true for any subquery row.
23729 The result is <quote>false</quote> if the comparison returns false for every
23730 subquery row (including the case where the subquery returns no
23731 rows).
23732 The result is NULL if no comparison with a subquery row returns true,
23733 and at least one comparison returns NULL.
23734 </para>
23736 <para>
23737 See <xref linkend="row-wise-comparison"/> for details about the meaning
23738 of a row constructor comparison.
23739 </para>
23740 </sect2>
23742 <sect2 id="functions-subquery-all">
23743 <title><literal>ALL</literal></title>
23745 <synopsis>
23746 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
23747 </synopsis>
23749 <para>
23750 The right-hand side is a parenthesized
23751 subquery, which must return exactly one column. The left-hand expression
23752 is evaluated and compared to each row of the subquery result using the
23753 given <replaceable>operator</replaceable>, which must yield a Boolean
23754 result.
23755 The result of <token>ALL</token> is <quote>true</quote> if all rows yield true
23756 (including the case where the subquery returns no rows).
23757 The result is <quote>false</quote> if any false result is found.
23758 The result is NULL if no comparison with a subquery row returns false,
23759 and at least one comparison returns NULL.
23760 </para>
23762 <para>
23763 <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
23764 </para>
23766 <para>
23767 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
23768 be evaluated completely.
23769 </para>
23771 <synopsis>
23772 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
23773 </synopsis>
23775 <para>
23776 The left-hand side of this form of <token>ALL</token> is a row constructor,
23777 as described in <xref linkend="sql-syntax-row-constructors"/>.
23778 The right-hand side is a parenthesized
23779 subquery, which must return exactly as many columns as there are
23780 expressions in the left-hand row. The left-hand expressions are
23781 evaluated and compared row-wise to each row of the subquery result,
23782 using the given <replaceable>operator</replaceable>.
23783 The result of <token>ALL</token> is <quote>true</quote> if the comparison
23784 returns true for all subquery rows (including the
23785 case where the subquery returns no rows).
23786 The result is <quote>false</quote> if the comparison returns false for any
23787 subquery row.
23788 The result is NULL if no comparison with a subquery row returns false,
23789 and at least one comparison returns NULL.
23790 </para>
23792 <para>
23793 See <xref linkend="row-wise-comparison"/> for details about the meaning
23794 of a row constructor comparison.
23795 </para>
23796 </sect2>
23798 <sect2 id="functions-subquery-single-row-comp">
23799 <title>Single-Row Comparison</title>
23801 <indexterm zone="functions-subquery">
23802 <primary>comparison</primary>
23803 <secondary>subquery result row</secondary>
23804 </indexterm>
23806 <synopsis>
23807 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
23808 </synopsis>
23810 <para>
23811 The left-hand side is a row constructor,
23812 as described in <xref linkend="sql-syntax-row-constructors"/>.
23813 The right-hand side is a parenthesized subquery, which must return exactly
23814 as many columns as there are expressions in the left-hand row. Furthermore,
23815 the subquery cannot return more than one row. (If it returns zero rows,
23816 the result is taken to be null.) The left-hand side is evaluated and
23817 compared row-wise to the single subquery result row.
23818 </para>
23820 <para>
23821 See <xref linkend="row-wise-comparison"/> for details about the meaning
23822 of a row constructor comparison.
23823 </para>
23824 </sect2>
23825 </sect1>
23828 <sect1 id="functions-comparisons">
23829 <title>Row and Array Comparisons</title>
23831 <indexterm>
23832 <primary>IN</primary>
23833 </indexterm>
23835 <indexterm>
23836 <primary>NOT IN</primary>
23837 </indexterm>
23839 <indexterm>
23840 <primary>ANY</primary>
23841 </indexterm>
23843 <indexterm>
23844 <primary>ALL</primary>
23845 </indexterm>
23847 <indexterm>
23848 <primary>SOME</primary>
23849 </indexterm>
23851 <indexterm>
23852 <primary>composite type</primary>
23853 <secondary>comparison</secondary>
23854 </indexterm>
23856 <indexterm>
23857 <primary>row-wise comparison</primary>
23858 </indexterm>
23860 <indexterm>
23861 <primary>comparison</primary>
23862 <secondary>composite type</secondary>
23863 </indexterm>
23865 <indexterm>
23866 <primary>comparison</primary>
23867 <secondary>row constructor</secondary>
23868 </indexterm>
23870 <indexterm>
23871 <primary>IS DISTINCT FROM</primary>
23872 </indexterm>
23874 <indexterm>
23875 <primary>IS NOT DISTINCT FROM</primary>
23876 </indexterm>
23878 <para>
23879 This section describes several specialized constructs for making
23880 multiple comparisons between groups of values. These forms are
23881 syntactically related to the subquery forms of the previous section,
23882 but do not involve subqueries.
23883 The forms involving array subexpressions are
23884 <productname>PostgreSQL</productname> extensions; the rest are
23885 <acronym>SQL</acronym>-compliant.
23886 All of the expression forms documented in this section return
23887 Boolean (true/false) results.
23888 </para>
23890 <sect2 id="functions-comparisons-in-scalar">
23891 <title><literal>IN</literal></title>
23893 <synopsis>
23894 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
23895 </synopsis>
23897 <para>
23898 The right-hand side is a parenthesized list
23899 of expressions. The result is <quote>true</quote> if the left-hand expression's
23900 result is equal to any of the right-hand expressions. This is a shorthand
23901 notation for
23903 <synopsis>
23904 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
23906 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
23909 </synopsis>
23910 </para>
23912 <para>
23913 Note that if the left-hand expression yields null, or if there are
23914 no equal right-hand values and at least one right-hand expression yields
23915 null, the result of the <token>IN</token> construct will be null, not false.
23916 This is in accordance with SQL's normal rules for Boolean combinations
23917 of null values.
23918 </para>
23919 </sect2>
23921 <sect2 id="functions-comparisons-not-in">
23922 <title><literal>NOT IN</literal></title>
23924 <synopsis>
23925 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
23926 </synopsis>
23928 <para>
23929 The right-hand side is a parenthesized list
23930 of expressions. The result is <quote>true</quote> if the left-hand expression's
23931 result is unequal to all of the right-hand expressions. This is a shorthand
23932 notation for
23934 <synopsis>
23935 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
23937 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
23940 </synopsis>
23941 </para>
23943 <para>
23944 Note that if the left-hand expression yields null, or if there are
23945 no equal right-hand values and at least one right-hand expression yields
23946 null, the result of the <token>NOT IN</token> construct will be null, not true
23947 as one might naively expect.
23948 This is in accordance with SQL's normal rules for Boolean combinations
23949 of null values.
23950 </para>
23952 <tip>
23953 <para>
23954 <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
23955 cases. However, null values are much more likely to trip up the novice when
23956 working with <token>NOT IN</token> than when working with <token>IN</token>.
23957 It is best to express your condition positively if possible.
23958 </para>
23959 </tip>
23960 </sect2>
23962 <sect2 id="functions-comparisons-any-some">
23963 <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
23965 <synopsis>
23966 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
23967 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
23968 </synopsis>
23970 <para>
23971 The right-hand side is a parenthesized expression, which must yield an
23972 array value.
23973 The left-hand expression
23974 is evaluated and compared to each element of the array using the
23975 given <replaceable>operator</replaceable>, which must yield a Boolean
23976 result.
23977 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
23978 The result is <quote>false</quote> if no true result is found (including the
23979 case where the array has zero elements).
23980 </para>
23982 <para>
23983 If the array expression yields a null array, the result of
23984 <token>ANY</token> will be null. If the left-hand expression yields null,
23985 the result of <token>ANY</token> is ordinarily null (though a non-strict
23986 comparison operator could possibly yield a different result).
23987 Also, if the right-hand array contains any null elements and no true
23988 comparison result is obtained, the result of <token>ANY</token>
23989 will be null, not false (again, assuming a strict comparison operator).
23990 This is in accordance with SQL's normal rules for Boolean combinations
23991 of null values.
23992 </para>
23994 <para>
23995 <token>SOME</token> is a synonym for <token>ANY</token>.
23996 </para>
23997 </sect2>
23999 <sect2 id="functions-comparisons-all">
24000 <title><literal>ALL</literal> (array)</title>
24002 <synopsis>
24003 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
24004 </synopsis>
24006 <para>
24007 The right-hand side is a parenthesized expression, which must yield an
24008 array value.
24009 The left-hand expression
24010 is evaluated and compared to each element of the array using the
24011 given <replaceable>operator</replaceable>, which must yield a Boolean
24012 result.
24013 The result of <token>ALL</token> is <quote>true</quote> if all comparisons yield true
24014 (including the case where the array has zero elements).
24015 The result is <quote>false</quote> if any false result is found.
24016 </para>
24018 <para>
24019 If the array expression yields a null array, the result of
24020 <token>ALL</token> will be null. If the left-hand expression yields null,
24021 the result of <token>ALL</token> is ordinarily null (though a non-strict
24022 comparison operator could possibly yield a different result).
24023 Also, if the right-hand array contains any null elements and no false
24024 comparison result is obtained, the result of <token>ALL</token>
24025 will be null, not true (again, assuming a strict comparison operator).
24026 This is in accordance with SQL's normal rules for Boolean combinations
24027 of null values.
24028 </para>
24029 </sect2>
24031 <sect2 id="row-wise-comparison">
24032 <title>Row Constructor Comparison</title>
24034 <synopsis>
24035 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
24036 </synopsis>
24038 <para>
24039 Each side is a row constructor,
24040 as described in <xref linkend="sql-syntax-row-constructors"/>.
24041 The two row constructors must have the same number of fields.
24042 The given <replaceable>operator</replaceable> is applied to each pair
24043 of corresponding fields. (Since the fields could be of different
24044 types, this means that a different specific operator could be selected
24045 for each pair.)
24046 All the selected operators must be members of some B-tree operator
24047 class, or be the negator of an <literal>=</literal> member of a B-tree
24048 operator class, meaning that row constructor comparison is only
24049 possible when the <replaceable>operator</replaceable> is
24050 <literal>=</literal>,
24051 <literal>&lt;&gt;</literal>,
24052 <literal>&lt;</literal>,
24053 <literal>&lt;=</literal>,
24054 <literal>&gt;</literal>, or
24055 <literal>&gt;=</literal>,
24056 or has semantics similar to one of these.
24057 </para>
24059 <para>
24060 The <literal>=</literal> and <literal>&lt;&gt;</literal> cases work slightly differently
24061 from the others. Two rows are considered
24062 equal if all their corresponding members are non-null and equal; the rows
24063 are unequal if any corresponding members are non-null and unequal;
24064 otherwise the result of the row comparison is unknown (null).
24065 </para>
24067 <para>
24068 For the <literal>&lt;</literal>, <literal>&lt;=</literal>, <literal>&gt;</literal> and
24069 <literal>&gt;=</literal> cases, the row elements are compared left-to-right,
24070 stopping as soon as an unequal or null pair of elements is found.
24071 If either of this pair of elements is null, the result of the
24072 row comparison is unknown (null); otherwise comparison of this pair
24073 of elements determines the result. For example,
24074 <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</literal>
24075 yields true, not null, because the third pair of elements are not
24076 considered.
24077 </para>
24079 <synopsis>
24080 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
24081 </synopsis>
24083 <para>
24084 This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
24085 but it does not yield null for null inputs. Instead, any null value is
24086 considered unequal to (distinct from) any non-null value, and any two
24087 nulls are considered equal (not distinct). Thus the result will
24088 either be true or false, never null.
24089 </para>
24091 <synopsis>
24092 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
24093 </synopsis>
24095 <para>
24096 This construct is similar to a <literal>=</literal> row comparison,
24097 but it does not yield null for null inputs. Instead, any null value is
24098 considered unequal to (distinct from) any non-null value, and any two
24099 nulls are considered equal (not distinct). Thus the result will always
24100 be either true or false, never null.
24101 </para>
24103 </sect2>
24105 <sect2 id="composite-type-comparison">
24106 <title>Composite Type Comparison</title>
24108 <synopsis>
24109 <replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
24110 </synopsis>
24112 <para>
24113 The SQL specification requires row-wise comparison to return NULL if the
24114 result depends on comparing two NULL values or a NULL and a non-NULL.
24115 <productname>PostgreSQL</productname> does this only when comparing the
24116 results of two row constructors (as in
24117 <xref linkend="row-wise-comparison"/>) or comparing a row constructor
24118 to the output of a subquery (as in <xref linkend="functions-subquery"/>).
24119 In other contexts where two composite-type values are compared, two
24120 NULL field values are considered equal, and a NULL is considered larger
24121 than a non-NULL. This is necessary in order to have consistent sorting
24122 and indexing behavior for composite types.
24123 </para>
24125 <para>
24126 Each side is evaluated and they are compared row-wise. Composite type
24127 comparisons are allowed when the <replaceable>operator</replaceable> is
24128 <literal>=</literal>,
24129 <literal>&lt;&gt;</literal>,
24130 <literal>&lt;</literal>,
24131 <literal>&lt;=</literal>,
24132 <literal>&gt;</literal> or
24133 <literal>&gt;=</literal>,
24134 or has semantics similar to one of these. (To be specific, an operator
24135 can be a row comparison operator if it is a member of a B-tree operator
24136 class, or is the negator of the <literal>=</literal> member of a B-tree operator
24137 class.) The default behavior of the above operators is the same as for
24138 <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
24139 <xref linkend="row-wise-comparison"/>).
24140 </para>
24142 <para>
24143 To support matching of rows which include elements without a default
24144 B-tree operator class, the following operators are defined for composite
24145 type comparison:
24146 <literal>*=</literal>,
24147 <literal>*&lt;&gt;</literal>,
24148 <literal>*&lt;</literal>,
24149 <literal>*&lt;=</literal>,
24150 <literal>*&gt;</literal>, and
24151 <literal>*&gt;=</literal>.
24152 These operators compare the internal binary representation of the two
24153 rows. Two rows might have a different binary representation even
24154 though comparisons of the two rows with the equality operator is true.
24155 The ordering of rows under these comparison operators is deterministic
24156 but not otherwise meaningful. These operators are used internally
24157 for materialized views and might be useful for other specialized
24158 purposes such as replication and B-Tree deduplication (see <xref
24159 linkend="btree-deduplication"/>). They are not intended to be
24160 generally useful for writing queries, though.
24161 </para>
24162 </sect2>
24163 </sect1>
24165 <sect1 id="functions-srf">
24166 <title>Set Returning Functions</title>
24168 <indexterm zone="functions-srf">
24169 <primary>set returning functions</primary>
24170 <secondary>functions</secondary>
24171 </indexterm>
24173 <para>
24174 This section describes functions that possibly return more than one row.
24175 The most widely used functions in this class are series generating
24176 functions, as detailed in <xref linkend="functions-srf-series"/> and
24177 <xref linkend="functions-srf-subscripts"/>. Other, more specialized
24178 set-returning functions are described elsewhere in this manual.
24179 See <xref linkend="queries-tablefunctions"/> for ways to combine multiple
24180 set-returning functions.
24181 </para>
24183 <table id="functions-srf-series">
24184 <title>Series Generating Functions</title>
24185 <tgroup cols="1">
24186 <thead>
24187 <row>
24188 <entry role="func_table_entry"><para role="func_signature">
24189 Function
24190 </para>
24191 <para>
24192 Description
24193 </para></entry>
24194 </row>
24195 </thead>
24197 <tbody>
24198 <row>
24199 <entry role="func_table_entry"><para role="func_signature">
24200 <indexterm>
24201 <primary>generate_series</primary>
24202 </indexterm>
24203 <function>generate_series</function> ( <parameter>start</parameter> <type>integer</type>, <parameter>stop</parameter> <type>integer</type> <optional>, <parameter>step</parameter> <type>integer</type> </optional> )
24204 <returnvalue>setof integer</returnvalue>
24205 </para>
24206 <para role="func_signature">
24207 <function>generate_series</function> ( <parameter>start</parameter> <type>bigint</type>, <parameter>stop</parameter> <type>bigint</type> <optional>, <parameter>step</parameter> <type>bigint</type> </optional> )
24208 <returnvalue>setof bigint</returnvalue>
24209 </para>
24210 <para role="func_signature">
24211 <function>generate_series</function> ( <parameter>start</parameter> <type>numeric</type>, <parameter>stop</parameter> <type>numeric</type> <optional>, <parameter>step</parameter> <type>numeric</type> </optional> )
24212 <returnvalue>setof numeric</returnvalue>
24213 </para>
24214 <para>
24215 Generates a series of values from <parameter>start</parameter>
24216 to <parameter>stop</parameter>, with a step size
24217 of <parameter>step</parameter>. <parameter>step</parameter>
24218 defaults to 1.
24219 </para></entry>
24220 </row>
24222 <row>
24223 <entry role="func_table_entry"><para role="func_signature">
24224 <function>generate_series</function> ( <parameter>start</parameter> <type>timestamp</type>, <parameter>stop</parameter> <type>timestamp</type>, <parameter>step</parameter> <type>interval</type> )
24225 <returnvalue>setof timestamp</returnvalue>
24226 </para>
24227 <para role="func_signature">
24228 <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> )
24229 <returnvalue>setof timestamp with time zone</returnvalue>
24230 </para>
24231 <para>
24232 Generates a series of values from <parameter>start</parameter>
24233 to <parameter>stop</parameter>, with a step size
24234 of <parameter>step</parameter>.
24235 In the timezone-aware form, times of day and daylight-savings
24236 adjustments are computed according to the time zone named by
24237 the <parameter>timezone</parameter> argument, or the current
24238 <xref linkend="guc-timezone"/> setting if that is omitted.
24239 </para></entry>
24240 </row>
24241 </tbody>
24242 </tgroup>
24243 </table>
24245 <para>
24246 When <parameter>step</parameter> is positive, zero rows are returned if
24247 <parameter>start</parameter> is greater than <parameter>stop</parameter>.
24248 Conversely, when <parameter>step</parameter> is negative, zero rows are
24249 returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
24250 Zero rows are also returned if any input is <literal>NULL</literal>.
24251 It is an error
24252 for <parameter>step</parameter> to be zero. Some examples follow:
24253 <programlisting>
24254 SELECT * FROM generate_series(2,4);
24255 generate_series
24256 -----------------
24260 (3 rows)
24262 SELECT * FROM generate_series(5,1,-2);
24263 generate_series
24264 -----------------
24268 (3 rows)
24270 SELECT * FROM generate_series(4,3);
24271 generate_series
24272 -----------------
24273 (0 rows)
24275 SELECT generate_series(1.1, 4, 1.3);
24276 generate_series
24277 -----------------
24281 (3 rows)
24283 -- this example relies on the date-plus-integer operator:
24284 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
24285 dates
24286 ------------
24287 2004-02-05
24288 2004-02-12
24289 2004-02-19
24290 (3 rows)
24292 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
24293 '2008-03-04 12:00', '10 hours');
24294 generate_series
24295 ---------------------
24296 2008-03-01 00:00:00
24297 2008-03-01 10:00:00
24298 2008-03-01 20:00:00
24299 2008-03-02 06:00:00
24300 2008-03-02 16:00:00
24301 2008-03-03 02:00:00
24302 2008-03-03 12:00:00
24303 2008-03-03 22:00:00
24304 2008-03-04 08:00:00
24305 (9 rows)
24307 -- this example assumes that TimeZone is set to UTC; note the DST transition:
24308 SELECT * FROM generate_series('2001-10-22 00:00 -04:00'::timestamptz,
24309 '2001-11-01 00:00 -05:00'::timestamptz,
24310 '1 day'::interval, 'America/New_York');
24311 generate_series
24312 ------------------------
24313 2001-10-22 04:00:00+00
24314 2001-10-23 04:00:00+00
24315 2001-10-24 04:00:00+00
24316 2001-10-25 04:00:00+00
24317 2001-10-26 04:00:00+00
24318 2001-10-27 04:00:00+00
24319 2001-10-28 04:00:00+00
24320 2001-10-29 05:00:00+00
24321 2001-10-30 05:00:00+00
24322 2001-10-31 05:00:00+00
24323 2001-11-01 05:00:00+00
24324 (11 rows)
24325 </programlisting>
24326 </para>
24328 <table id="functions-srf-subscripts">
24329 <title>Subscript Generating Functions</title>
24330 <tgroup cols="1">
24331 <thead>
24332 <row>
24333 <entry role="func_table_entry"><para role="func_signature">
24334 Function
24335 </para>
24336 <para>
24337 Description
24338 </para></entry>
24339 </row>
24340 </thead>
24342 <tbody>
24343 <row>
24344 <entry role="func_table_entry"><para role="func_signature">
24345 <indexterm>
24346 <primary>generate_subscripts</primary>
24347 </indexterm>
24348 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type> )
24349 <returnvalue>setof integer</returnvalue>
24350 </para>
24351 <para>
24352 Generates a series comprising the valid subscripts of
24353 the <parameter>dim</parameter>'th dimension of the given array.
24354 </para></entry>
24355 </row>
24357 <row>
24358 <entry role="func_table_entry"><para role="func_signature">
24359 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type>, <parameter>reverse</parameter> <type>boolean</type> )
24360 <returnvalue>setof integer</returnvalue>
24361 </para>
24362 <para>
24363 Generates a series comprising the valid subscripts of
24364 the <parameter>dim</parameter>'th dimension of the given array.
24365 When <parameter>reverse</parameter> is true, returns the series in
24366 reverse order.
24367 </para></entry>
24368 </row>
24369 </tbody>
24370 </tgroup>
24371 </table>
24373 <para>
24374 <function>generate_subscripts</function> is a convenience function that generates
24375 the set of valid subscripts for the specified dimension of the given
24376 array.
24377 Zero rows are returned for arrays that do not have the requested dimension,
24378 or if any input is <literal>NULL</literal>.
24379 Some examples follow:
24380 <programlisting>
24381 -- basic usage:
24382 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
24389 (4 rows)
24391 -- presenting an array, the subscript and the subscripted
24392 -- value requires a subquery:
24393 SELECT * FROM arrays;
24395 --------------------
24396 {-1,-2}
24397 {100,200,300}
24398 (2 rows)
24400 SELECT a AS array, s AS subscript, a[s] AS value
24401 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
24402 array | subscript | value
24403 ---------------+-----------+-------
24404 {-1,-2} | 1 | -1
24405 {-1,-2} | 2 | -2
24406 {100,200,300} | 1 | 100
24407 {100,200,300} | 2 | 200
24408 {100,200,300} | 3 | 300
24409 (5 rows)
24411 -- unnest a 2D array:
24412 CREATE OR REPLACE FUNCTION unnest2(anyarray)
24413 RETURNS SETOF anyelement AS $$
24414 select $1[i][j]
24415 from generate_subscripts($1,1) g1(i),
24416 generate_subscripts($1,2) g2(j);
24417 $$ LANGUAGE sql IMMUTABLE;
24418 CREATE FUNCTION
24419 SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
24420 unnest2
24421 ---------
24426 (4 rows)
24427 </programlisting>
24428 </para>
24430 <indexterm>
24431 <primary>ordinality</primary>
24432 </indexterm>
24434 <para>
24435 When a function in the <literal>FROM</literal> clause is suffixed
24436 by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is
24437 appended to the function's output column(s), which starts from 1 and
24438 increments by 1 for each row of the function's output.
24439 This is most useful in the case of set returning
24440 functions such as <function>unnest()</function>.
24442 <programlisting>
24443 -- set returning function WITH ORDINALITY:
24444 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
24445 ls | n
24446 -----------------+----
24447 pg_serial | 1
24448 pg_twophase | 2
24449 postmaster.opts | 3
24450 pg_notify | 4
24451 postgresql.conf | 5
24452 pg_tblspc | 6
24453 logfile | 7
24454 base | 8
24455 postmaster.pid | 9
24456 pg_ident.conf | 10
24457 global | 11
24458 pg_xact | 12
24459 pg_snapshots | 13
24460 pg_multixact | 14
24461 PG_VERSION | 15
24462 pg_wal | 16
24463 pg_hba.conf | 17
24464 pg_stat_tmp | 18
24465 pg_subtrans | 19
24466 (19 rows)
24467 </programlisting>
24468 </para>
24470 </sect1>
24472 <sect1 id="functions-info">
24473 <title>System Information Functions and Operators</title>
24475 <para>
24476 The functions described in this section are used to obtain various
24477 information about a <productname>PostgreSQL</productname> installation.
24478 </para>
24480 <sect2 id="functions-info-session">
24481 <title>Session Information Functions</title>
24483 <para>
24484 <xref linkend="functions-info-session-table"/> shows several
24485 functions that extract session and system information.
24486 </para>
24488 <para>
24489 In addition to the functions listed in this section, there are a number of
24490 functions related to the statistics system that also provide system
24491 information. See <xref linkend="monitoring-stats-functions"/> for more
24492 information.
24493 </para>
24495 <table id="functions-info-session-table">
24496 <title>Session Information Functions</title>
24497 <tgroup cols="1">
24498 <thead>
24499 <row>
24500 <entry role="func_table_entry"><para role="func_signature">
24501 Function
24502 </para>
24503 <para>
24504 Description
24505 </para></entry>
24506 </row>
24507 </thead>
24509 <tbody>
24510 <row>
24511 <entry role="func_table_entry"><para role="func_signature">
24512 <indexterm>
24513 <primary>current_catalog</primary>
24514 </indexterm>
24515 <function>current_catalog</function>
24516 <returnvalue>name</returnvalue>
24517 </para>
24518 <para role="func_signature">
24519 <indexterm>
24520 <primary>current_database</primary>
24521 </indexterm>
24522 <function>current_database</function> ()
24523 <returnvalue>name</returnvalue>
24524 </para>
24525 <para>
24526 Returns the name of the current database. (Databases are
24527 called <quote>catalogs</quote> in the SQL standard,
24528 so <function>current_catalog</function> is the standard's
24529 spelling.)
24530 </para></entry>
24531 </row>
24533 <row>
24534 <entry role="func_table_entry"><para role="func_signature">
24535 <indexterm>
24536 <primary>current_query</primary>
24537 </indexterm>
24538 <function>current_query</function> ()
24539 <returnvalue>text</returnvalue>
24540 </para>
24541 <para>
24542 Returns the text of the currently executing query, as submitted
24543 by the client (which might contain more than one statement).
24544 </para></entry>
24545 </row>
24547 <row>
24548 <entry role="func_table_entry"><para role="func_signature">
24549 <indexterm>
24550 <primary>current_role</primary>
24551 </indexterm>
24552 <function>current_role</function>
24553 <returnvalue>name</returnvalue>
24554 </para>
24555 <para>
24556 This is equivalent to <function>current_user</function>.
24557 </para></entry>
24558 </row>
24560 <row>
24561 <entry role="func_table_entry"><para role="func_signature">
24562 <indexterm>
24563 <primary>current_schema</primary>
24564 </indexterm>
24565 <indexterm>
24566 <primary>schema</primary>
24567 <secondary>current</secondary>
24568 </indexterm>
24569 <function>current_schema</function>
24570 <returnvalue>name</returnvalue>
24571 </para>
24572 <para role="func_signature">
24573 <function>current_schema</function> ()
24574 <returnvalue>name</returnvalue>
24575 </para>
24576 <para>
24577 Returns the name of the schema that is first in the search path (or a
24578 null value if the search path is empty). This is the schema that will
24579 be used for any tables or other named objects that are created without
24580 specifying a target schema.
24581 </para></entry>
24582 </row>
24584 <row>
24585 <entry role="func_table_entry"><para role="func_signature">
24586 <indexterm>
24587 <primary>current_schemas</primary>
24588 </indexterm>
24589 <indexterm>
24590 <primary>search path</primary>
24591 <secondary>current</secondary>
24592 </indexterm>
24593 <function>current_schemas</function> ( <parameter>include_implicit</parameter> <type>boolean</type> )
24594 <returnvalue>name[]</returnvalue>
24595 </para>
24596 <para>
24597 Returns an array of the names of all schemas presently in the
24598 effective search path, in their priority order. (Items in the current
24599 <xref linkend="guc-search-path"/> setting that do not correspond to
24600 existing, searchable schemas are omitted.) If the Boolean argument
24601 is <literal>true</literal>, then implicitly-searched system schemas
24602 such as <literal>pg_catalog</literal> are included in the result.
24603 </para></entry>
24604 </row>
24606 <row>
24607 <entry role="func_table_entry"><para role="func_signature">
24608 <indexterm>
24609 <primary>current_user</primary>
24610 </indexterm>
24611 <indexterm>
24612 <primary>user</primary>
24613 <secondary>current</secondary>
24614 </indexterm>
24615 <function>current_user</function>
24616 <returnvalue>name</returnvalue>
24617 </para>
24618 <para>
24619 Returns the user name of the current execution context.
24620 </para></entry>
24621 </row>
24623 <row>
24624 <entry role="func_table_entry"><para role="func_signature">
24625 <indexterm>
24626 <primary>inet_client_addr</primary>
24627 </indexterm>
24628 <function>inet_client_addr</function> ()
24629 <returnvalue>inet</returnvalue>
24630 </para>
24631 <para>
24632 Returns the IP address of the current client,
24633 or <literal>NULL</literal> if the current connection is via a
24634 Unix-domain socket.
24635 </para></entry>
24636 </row>
24638 <row>
24639 <entry role="func_table_entry"><para role="func_signature">
24640 <indexterm>
24641 <primary>inet_client_port</primary>
24642 </indexterm>
24643 <function>inet_client_port</function> ()
24644 <returnvalue>integer</returnvalue>
24645 </para>
24646 <para>
24647 Returns the IP port number of the current client,
24648 or <literal>NULL</literal> if the current connection is via a
24649 Unix-domain socket.
24650 </para></entry>
24651 </row>
24653 <row>
24654 <entry role="func_table_entry"><para role="func_signature">
24655 <indexterm>
24656 <primary>inet_server_addr</primary>
24657 </indexterm>
24658 <function>inet_server_addr</function> ()
24659 <returnvalue>inet</returnvalue>
24660 </para>
24661 <para>
24662 Returns the IP address on which the server accepted the current
24663 connection,
24664 or <literal>NULL</literal> if the current connection is via a
24665 Unix-domain socket.
24666 </para></entry>
24667 </row>
24669 <row>
24670 <entry role="func_table_entry"><para role="func_signature">
24671 <indexterm>
24672 <primary>inet_server_port</primary>
24673 </indexterm>
24674 <function>inet_server_port</function> ()
24675 <returnvalue>integer</returnvalue>
24676 </para>
24677 <para>
24678 Returns the IP port number on which the server accepted the current
24679 connection,
24680 or <literal>NULL</literal> if the current connection is via a
24681 Unix-domain socket.
24682 </para></entry>
24683 </row>
24685 <row>
24686 <entry role="func_table_entry"><para role="func_signature">
24687 <indexterm>
24688 <primary>pg_backend_pid</primary>
24689 </indexterm>
24690 <function>pg_backend_pid</function> ()
24691 <returnvalue>integer</returnvalue>
24692 </para>
24693 <para>
24694 Returns the process ID of the server process attached to the current
24695 session.
24696 </para></entry>
24697 </row>
24699 <row>
24700 <entry role="func_table_entry"><para role="func_signature">
24701 <indexterm>
24702 <primary>pg_blocking_pids</primary>
24703 </indexterm>
24704 <function>pg_blocking_pids</function> ( <type>integer</type> )
24705 <returnvalue>integer[]</returnvalue>
24706 </para>
24707 <para>
24708 Returns an array of the process ID(s) of the sessions that are
24709 blocking the server process with the specified process ID from
24710 acquiring a lock, or an empty array if there is no such server process
24711 or it is not blocked.
24712 </para>
24713 <para>
24714 One server process blocks another if it either holds a lock that
24715 conflicts with the blocked process's lock request (hard block), or is
24716 waiting for a lock that would conflict with the blocked process's lock
24717 request and is ahead of it in the wait queue (soft block). When using
24718 parallel queries the result always lists client-visible process IDs
24719 (that is, <function>pg_backend_pid</function> results) even if the
24720 actual lock is held or awaited by a child worker process. As a result
24721 of that, there may be duplicated PIDs in the result. Also note that
24722 when a prepared transaction holds a conflicting lock, it will be
24723 represented by a zero process ID.
24724 </para>
24725 <para>
24726 Frequent calls to this function could have some impact on database
24727 performance, because it needs exclusive access to the lock manager's
24728 shared state for a short time.
24729 </para></entry>
24730 </row>
24732 <row>
24733 <entry role="func_table_entry"><para role="func_signature">
24734 <indexterm>
24735 <primary>pg_conf_load_time</primary>
24736 </indexterm>
24737 <function>pg_conf_load_time</function> ()
24738 <returnvalue>timestamp with time zone</returnvalue>
24739 </para>
24740 <para>
24741 Returns the time when the server configuration files were last loaded.
24742 If the current session was alive at the time, this will be the time
24743 when the session itself re-read the configuration files (so the
24744 reading will vary a little in different sessions). Otherwise it is
24745 the time when the postmaster process re-read the configuration files.
24746 </para></entry>
24747 </row>
24749 <row>
24750 <entry role="func_table_entry"><para role="func_signature">
24751 <indexterm>
24752 <primary>pg_current_logfile</primary>
24753 </indexterm>
24754 <indexterm>
24755 <primary>Logging</primary>
24756 <secondary>pg_current_logfile function</secondary>
24757 </indexterm>
24758 <indexterm>
24759 <primary>current_logfiles</primary>
24760 <secondary>and the pg_current_logfile function</secondary>
24761 </indexterm>
24762 <indexterm>
24763 <primary>Logging</primary>
24764 <secondary>current_logfiles file and the pg_current_logfile
24765 function</secondary>
24766 </indexterm>
24767 <function>pg_current_logfile</function> ( <optional> <type>text</type> </optional> )
24768 <returnvalue>text</returnvalue>
24769 </para>
24770 <para>
24771 Returns the path name of the log file currently in use by the logging
24772 collector. The path includes the <xref linkend="guc-log-directory"/>
24773 directory and the individual log file name. The result
24774 is <literal>NULL</literal> if the logging collector is disabled.
24775 When multiple log files exist, each in a different
24776 format, <function>pg_current_logfile</function> without an argument
24777 returns the path of the file having the first format found in the
24778 ordered list: <literal>stderr</literal>,
24779 <literal>csvlog</literal>, <literal>jsonlog</literal>.
24780 <literal>NULL</literal> is returned if no log file has any of these
24781 formats.
24782 To request information about a specific log file format, supply
24783 either <literal>csvlog</literal>, <literal>jsonlog</literal> or
24784 <literal>stderr</literal> as the
24785 value of the optional parameter. The result is <literal>NULL</literal>
24786 if the log format requested is not configured in
24787 <xref linkend="guc-log-destination"/>.
24788 The result reflects the contents of
24789 the <filename>current_logfiles</filename> file.
24790 </para>
24791 <para>
24792 This function is restricted to superusers and roles with privileges of
24793 the <literal>pg_monitor</literal> role by default, but other users can
24794 be granted EXECUTE to run the function.
24795 </para></entry>
24796 </row>
24798 <row>
24799 <entry role="func_table_entry"><para role="func_signature">
24800 <indexterm>
24801 <primary>pg_my_temp_schema</primary>
24802 </indexterm>
24803 <function>pg_my_temp_schema</function> ()
24804 <returnvalue>oid</returnvalue>
24805 </para>
24806 <para>
24807 Returns the OID of the current session's temporary schema, or zero if
24808 it has none (because it has not created any temporary tables).
24809 </para></entry>
24810 </row>
24812 <row>
24813 <entry role="func_table_entry"><para role="func_signature">
24814 <indexterm>
24815 <primary>pg_is_other_temp_schema</primary>
24816 </indexterm>
24817 <function>pg_is_other_temp_schema</function> ( <type>oid</type> )
24818 <returnvalue>boolean</returnvalue>
24819 </para>
24820 <para>
24821 Returns true if the given OID is the OID of another session's
24822 temporary schema. (This can be useful, for example, to exclude other
24823 sessions' temporary tables from a catalog display.)
24824 </para></entry>
24825 </row>
24827 <row>
24828 <entry role="func_table_entry"><para role="func_signature">
24829 <indexterm>
24830 <primary>pg_jit_available</primary>
24831 </indexterm>
24832 <function>pg_jit_available</function> ()
24833 <returnvalue>boolean</returnvalue>
24834 </para>
24835 <para>
24836 Returns true if a <acronym>JIT</acronym> compiler extension is
24837 available (see <xref linkend="jit"/>) and the
24838 <xref linkend="guc-jit"/> configuration parameter is set to
24839 <literal>on</literal>.
24840 </para></entry>
24841 </row>
24843 <row>
24844 <entry role="func_table_entry"><para role="func_signature">
24845 <indexterm>
24846 <primary>pg_listening_channels</primary>
24847 </indexterm>
24848 <function>pg_listening_channels</function> ()
24849 <returnvalue>setof text</returnvalue>
24850 </para>
24851 <para>
24852 Returns the set of names of asynchronous notification channels that
24853 the current session is listening to.
24854 </para></entry>
24855 </row>
24857 <row>
24858 <entry role="func_table_entry"><para role="func_signature">
24859 <indexterm>
24860 <primary>pg_notification_queue_usage</primary>
24861 </indexterm>
24862 <function>pg_notification_queue_usage</function> ()
24863 <returnvalue>double precision</returnvalue>
24864 </para>
24865 <para>
24866 Returns the fraction (0&ndash;1) of the asynchronous notification
24867 queue's maximum size that is currently occupied by notifications that
24868 are waiting to be processed.
24869 See <xref linkend="sql-listen"/> and <xref linkend="sql-notify"/>
24870 for more information.
24871 </para></entry>
24872 </row>
24874 <row>
24875 <entry role="func_table_entry"><para role="func_signature">
24876 <indexterm>
24877 <primary>pg_postmaster_start_time</primary>
24878 </indexterm>
24879 <function>pg_postmaster_start_time</function> ()
24880 <returnvalue>timestamp with time zone</returnvalue>
24881 </para>
24882 <para>
24883 Returns the time when the server started.
24884 </para></entry>
24885 </row>
24887 <row>
24888 <entry role="func_table_entry"><para role="func_signature">
24889 <indexterm>
24890 <primary>pg_safe_snapshot_blocking_pids</primary>
24891 </indexterm>
24892 <function>pg_safe_snapshot_blocking_pids</function> ( <type>integer</type> )
24893 <returnvalue>integer[]</returnvalue>
24894 </para>
24895 <para>
24896 Returns an array of the process ID(s) of the sessions that are blocking
24897 the server process with the specified process ID from acquiring a safe
24898 snapshot, or an empty array if there is no such server process or it
24899 is not blocked.
24900 </para>
24901 <para>
24902 A session running a <literal>SERIALIZABLE</literal> transaction blocks
24903 a <literal>SERIALIZABLE READ ONLY DEFERRABLE</literal> transaction
24904 from acquiring a snapshot until the latter determines that it is safe
24905 to avoid taking any predicate locks. See
24906 <xref linkend="xact-serializable"/> for more information about
24907 serializable and deferrable transactions.
24908 </para>
24909 <para>
24910 Frequent calls to this function could have some impact on database
24911 performance, because it needs access to the predicate lock manager's
24912 shared state for a short time.
24913 </para></entry>
24914 </row>
24916 <row>
24917 <entry role="func_table_entry"><para role="func_signature">
24918 <indexterm>
24919 <primary>pg_trigger_depth</primary>
24920 </indexterm>
24921 <function>pg_trigger_depth</function> ()
24922 <returnvalue>integer</returnvalue>
24923 </para>
24924 <para>
24925 Returns the current nesting level
24926 of <productname>PostgreSQL</productname> triggers (0 if not called,
24927 directly or indirectly, from inside a trigger).
24928 </para></entry>
24929 </row>
24931 <row>
24932 <entry role="func_table_entry"><para role="func_signature">
24933 <indexterm>
24934 <primary>session_user</primary>
24935 </indexterm>
24936 <function>session_user</function>
24937 <returnvalue>name</returnvalue>
24938 </para>
24939 <para>
24940 Returns the session user's name.
24941 </para></entry>
24942 </row>
24944 <row>
24945 <entry role="func_table_entry"><para role="func_signature">
24946 <indexterm>
24947 <primary>system_user</primary>
24948 </indexterm>
24949 <function>system_user</function>
24950 <returnvalue>text</returnvalue>
24951 </para>
24952 <para>
24953 Returns the authentication method and the identity (if any) that the
24954 user presented during the authentication cycle before they were
24955 assigned a database role. It is represented as
24956 <literal>auth_method:identity</literal> or
24957 <literal>NULL</literal> if the user has not been authenticated (for
24958 example if <link linkend="auth-trust">Trust authentication</link> has
24959 been used).
24960 </para></entry>
24961 </row>
24963 <row>
24964 <entry role="func_table_entry"><para role="func_signature">
24965 <indexterm>
24966 <primary>user</primary>
24967 </indexterm>
24968 <function>user</function>
24969 <returnvalue>name</returnvalue>
24970 </para>
24971 <para>
24972 This is equivalent to <function>current_user</function>.
24973 </para></entry>
24974 </row>
24975 </tbody>
24976 </tgroup>
24977 </table>
24979 <note>
24980 <para>
24981 <function>current_catalog</function>,
24982 <function>current_role</function>,
24983 <function>current_schema</function>,
24984 <function>current_user</function>,
24985 <function>session_user</function>,
24986 and <function>user</function> have special syntactic status
24987 in <acronym>SQL</acronym>: they must be called without trailing
24988 parentheses. In PostgreSQL, parentheses can optionally be used with
24989 <function>current_schema</function>, but not with the others.
24990 </para>
24991 </note>
24993 <para>
24994 The <function>session_user</function> is normally the user who initiated
24995 the current database connection; but superusers can change this setting
24996 with <xref linkend="sql-set-session-authorization"/>.
24997 The <function>current_user</function> is the user identifier
24998 that is applicable for permission checking. Normally it is equal
24999 to the session user, but it can be changed with
25000 <xref linkend="sql-set-role"/>.
25001 It also changes during the execution of
25002 functions with the attribute <literal>SECURITY DEFINER</literal>.
25003 In Unix parlance, the session user is the <quote>real user</quote> and
25004 the current user is the <quote>effective user</quote>.
25005 <function>current_role</function> and <function>user</function> are
25006 synonyms for <function>current_user</function>. (The SQL standard draws
25007 a distinction between <function>current_role</function>
25008 and <function>current_user</function>, but <productname>PostgreSQL</productname>
25009 does not, since it unifies users and roles into a single kind of entity.)
25010 </para>
25012 </sect2>
25014 <sect2 id="functions-info-access">
25015 <title>Access Privilege Inquiry Functions</title>
25017 <indexterm>
25018 <primary>privilege</primary>
25019 <secondary>querying</secondary>
25020 </indexterm>
25022 <para>
25023 <xref linkend="functions-info-access-table"/> lists functions that
25024 allow querying object access privileges programmatically.
25025 (See <xref linkend="ddl-priv"/> for more information about
25026 privileges.)
25027 In these functions, the user whose privileges are being inquired about
25028 can be specified by name or by OID
25029 (<structname>pg_authid</structname>.<structfield>oid</structfield>), or if
25030 the name is given as <literal>public</literal> then the privileges of the
25031 PUBLIC pseudo-role are checked. Also, the <parameter>user</parameter>
25032 argument can be omitted entirely, in which case
25033 the <function>current_user</function> is assumed.
25034 The object that is being inquired about can be specified either by name or
25035 by OID, too. When specifying by name, a schema name can be included if
25036 relevant.
25037 The access privilege of interest is specified by a text string, which must
25038 evaluate to one of the appropriate privilege keywords for the object's type
25039 (e.g., <literal>SELECT</literal>). Optionally, <literal>WITH GRANT
25040 OPTION</literal> can be added to a privilege type to test whether the
25041 privilege is held with grant option. Also, multiple privilege types can be
25042 listed separated by commas, in which case the result will be true if any of
25043 the listed privileges is held. (Case of the privilege string is not
25044 significant, and extra whitespace is allowed between but not within
25045 privilege names.)
25046 Some examples:
25047 <programlisting>
25048 SELECT has_table_privilege('myschema.mytable', 'select');
25049 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
25050 </programlisting>
25051 </para>
25053 <table id="functions-info-access-table">
25054 <title>Access Privilege Inquiry Functions</title>
25055 <tgroup cols="1">
25056 <thead>
25057 <row>
25058 <entry role="func_table_entry"><para role="func_signature">
25059 Function
25060 </para>
25061 <para>
25062 Description
25063 </para></entry>
25064 </row>
25065 </thead>
25067 <tbody>
25068 <row>
25069 <entry role="func_table_entry"><para role="func_signature">
25070 <indexterm>
25071 <primary>has_any_column_privilege</primary>
25072 </indexterm>
25073 <function>has_any_column_privilege</function> (
25074 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25075 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
25076 <parameter>privilege</parameter> <type>text</type> )
25077 <returnvalue>boolean</returnvalue>
25078 </para>
25079 <para>
25080 Does user have privilege for any column of table?
25081 This succeeds either if the privilege is held for the whole table, or
25082 if there is a column-level grant of the privilege for at least one
25083 column.
25084 Allowable privilege types are
25085 <literal>SELECT</literal>, <literal>INSERT</literal>,
25086 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
25087 </para></entry>
25088 </row>
25090 <row>
25091 <entry role="func_table_entry"><para role="func_signature">
25092 <indexterm>
25093 <primary>has_column_privilege</primary>
25094 </indexterm>
25095 <function>has_column_privilege</function> (
25096 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25097 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
25098 <parameter>column</parameter> <type>text</type> or <type>smallint</type>,
25099 <parameter>privilege</parameter> <type>text</type> )
25100 <returnvalue>boolean</returnvalue>
25101 </para>
25102 <para>
25103 Does user have privilege for the specified table column?
25104 This succeeds either if the privilege is held for the whole table, or
25105 if there is a column-level grant of the privilege for the column.
25106 The column can be specified by name or by attribute number
25107 (<structname>pg_attribute</structname>.<structfield>attnum</structfield>).
25108 Allowable privilege types are
25109 <literal>SELECT</literal>, <literal>INSERT</literal>,
25110 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
25111 </para></entry>
25112 </row>
25114 <row>
25115 <entry role="func_table_entry"><para role="func_signature">
25116 <indexterm>
25117 <primary>has_database_privilege</primary>
25118 </indexterm>
25119 <function>has_database_privilege</function> (
25120 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25121 <parameter>database</parameter> <type>text</type> or <type>oid</type>,
25122 <parameter>privilege</parameter> <type>text</type> )
25123 <returnvalue>boolean</returnvalue>
25124 </para>
25125 <para>
25126 Does user have privilege for database?
25127 Allowable privilege types are
25128 <literal>CREATE</literal>,
25129 <literal>CONNECT</literal>,
25130 <literal>TEMPORARY</literal>, and
25131 <literal>TEMP</literal> (which is equivalent to
25132 <literal>TEMPORARY</literal>).
25133 </para></entry>
25134 </row>
25136 <row>
25137 <entry role="func_table_entry"><para role="func_signature">
25138 <indexterm>
25139 <primary>has_foreign_data_wrapper_privilege</primary>
25140 </indexterm>
25141 <function>has_foreign_data_wrapper_privilege</function> (
25142 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25143 <parameter>fdw</parameter> <type>text</type> or <type>oid</type>,
25144 <parameter>privilege</parameter> <type>text</type> )
25145 <returnvalue>boolean</returnvalue>
25146 </para>
25147 <para>
25148 Does user have privilege for foreign-data wrapper?
25149 The only allowable privilege type is <literal>USAGE</literal>.
25150 </para></entry>
25151 </row>
25153 <row>
25154 <entry role="func_table_entry"><para role="func_signature">
25155 <indexterm>
25156 <primary>has_function_privilege</primary>
25157 </indexterm>
25158 <function>has_function_privilege</function> (
25159 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25160 <parameter>function</parameter> <type>text</type> or <type>oid</type>,
25161 <parameter>privilege</parameter> <type>text</type> )
25162 <returnvalue>boolean</returnvalue>
25163 </para>
25164 <para>
25165 Does user have privilege for function?
25166 The only allowable privilege type is <literal>EXECUTE</literal>.
25167 </para>
25168 <para>
25169 When specifying a function by name rather than by OID, the allowed
25170 input is the same as for the <type>regprocedure</type> data type (see
25171 <xref linkend="datatype-oid"/>).
25172 An example is:
25173 <programlisting>
25174 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
25175 </programlisting>
25176 </para></entry>
25177 </row>
25179 <row>
25180 <entry role="func_table_entry"><para role="func_signature">
25181 <indexterm>
25182 <primary>has_language_privilege</primary>
25183 </indexterm>
25184 <function>has_language_privilege</function> (
25185 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25186 <parameter>language</parameter> <type>text</type> or <type>oid</type>,
25187 <parameter>privilege</parameter> <type>text</type> )
25188 <returnvalue>boolean</returnvalue>
25189 </para>
25190 <para>
25191 Does user have privilege for language?
25192 The only allowable privilege type is <literal>USAGE</literal>.
25193 </para></entry>
25194 </row>
25196 <row>
25197 <entry role="func_table_entry"><para role="func_signature">
25198 <indexterm>
25199 <primary>has_largeobject_privilege</primary>
25200 </indexterm>
25201 <function>has_largeobject_privilege</function> (
25202 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25203 <parameter>largeobject</parameter> <type>oid</type>,
25204 <parameter>privilege</parameter> <type>text</type> )
25205 <returnvalue>boolean</returnvalue>
25206 </para>
25207 <para>
25208 Does user have privilege for large object?
25209 Allowable privilege types are
25210 <literal>SELECT</literal> and <literal>UPDATE</literal>.
25211 </para></entry>
25212 </row>
25214 <row>
25215 <entry role="func_table_entry"><para role="func_signature">
25216 <indexterm>
25217 <primary>has_parameter_privilege</primary>
25218 </indexterm>
25219 <function>has_parameter_privilege</function> (
25220 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25221 <parameter>parameter</parameter> <type>text</type>,
25222 <parameter>privilege</parameter> <type>text</type> )
25223 <returnvalue>boolean</returnvalue>
25224 </para>
25225 <para>
25226 Does user have privilege for configuration parameter?
25227 The parameter name is case-insensitive.
25228 Allowable privilege types are <literal>SET</literal>
25229 and <literal>ALTER SYSTEM</literal>.
25230 </para></entry>
25231 </row>
25233 <row>
25234 <entry role="func_table_entry"><para role="func_signature">
25235 <indexterm>
25236 <primary>has_schema_privilege</primary>
25237 </indexterm>
25238 <function>has_schema_privilege</function> (
25239 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25240 <parameter>schema</parameter> <type>text</type> or <type>oid</type>,
25241 <parameter>privilege</parameter> <type>text</type> )
25242 <returnvalue>boolean</returnvalue>
25243 </para>
25244 <para>
25245 Does user have privilege for schema?
25246 Allowable privilege types are
25247 <literal>CREATE</literal> and
25248 <literal>USAGE</literal>.
25249 </para></entry>
25250 </row>
25252 <row>
25253 <entry role="func_table_entry"><para role="func_signature">
25254 <indexterm>
25255 <primary>has_sequence_privilege</primary>
25256 </indexterm>
25257 <function>has_sequence_privilege</function> (
25258 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25259 <parameter>sequence</parameter> <type>text</type> or <type>oid</type>,
25260 <parameter>privilege</parameter> <type>text</type> )
25261 <returnvalue>boolean</returnvalue>
25262 </para>
25263 <para>
25264 Does user have privilege for sequence?
25265 Allowable privilege types are
25266 <literal>USAGE</literal>,
25267 <literal>SELECT</literal>, and
25268 <literal>UPDATE</literal>.
25269 </para></entry>
25270 </row>
25272 <row>
25273 <entry role="func_table_entry"><para role="func_signature">
25274 <indexterm>
25275 <primary>has_server_privilege</primary>
25276 </indexterm>
25277 <function>has_server_privilege</function> (
25278 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25279 <parameter>server</parameter> <type>text</type> or <type>oid</type>,
25280 <parameter>privilege</parameter> <type>text</type> )
25281 <returnvalue>boolean</returnvalue>
25282 </para>
25283 <para>
25284 Does user have privilege for foreign server?
25285 The only allowable privilege type is <literal>USAGE</literal>.
25286 </para></entry>
25287 </row>
25289 <row>
25290 <entry role="func_table_entry"><para role="func_signature">
25291 <indexterm>
25292 <primary>has_table_privilege</primary>
25293 </indexterm>
25294 <function>has_table_privilege</function> (
25295 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25296 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
25297 <parameter>privilege</parameter> <type>text</type> )
25298 <returnvalue>boolean</returnvalue>
25299 </para>
25300 <para>
25301 Does user have privilege for table?
25302 Allowable privilege types
25303 are <literal>SELECT</literal>, <literal>INSERT</literal>,
25304 <literal>UPDATE</literal>, <literal>DELETE</literal>,
25305 <literal>TRUNCATE</literal>, <literal>REFERENCES</literal>,
25306 <literal>TRIGGER</literal>, and <literal>MAINTAIN</literal>.
25307 </para></entry>
25308 </row>
25310 <row>
25311 <entry role="func_table_entry"><para role="func_signature">
25312 <indexterm>
25313 <primary>has_tablespace_privilege</primary>
25314 </indexterm>
25315 <function>has_tablespace_privilege</function> (
25316 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25317 <parameter>tablespace</parameter> <type>text</type> or <type>oid</type>,
25318 <parameter>privilege</parameter> <type>text</type> )
25319 <returnvalue>boolean</returnvalue>
25320 </para>
25321 <para>
25322 Does user have privilege for tablespace?
25323 The only allowable privilege type is <literal>CREATE</literal>.
25324 </para></entry>
25325 </row>
25327 <row>
25328 <entry role="func_table_entry"><para role="func_signature">
25329 <indexterm>
25330 <primary>has_type_privilege</primary>
25331 </indexterm>
25332 <function>has_type_privilege</function> (
25333 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25334 <parameter>type</parameter> <type>text</type> or <type>oid</type>,
25335 <parameter>privilege</parameter> <type>text</type> )
25336 <returnvalue>boolean</returnvalue>
25337 </para>
25338 <para>
25339 Does user have privilege for data type?
25340 The only allowable privilege type is <literal>USAGE</literal>.
25341 When specifying a type by name rather than by OID, the allowed input
25342 is the same as for the <type>regtype</type> data type (see
25343 <xref linkend="datatype-oid"/>).
25344 </para></entry>
25345 </row>
25347 <row>
25348 <entry role="func_table_entry"><para role="func_signature">
25349 <indexterm>
25350 <primary>pg_has_role</primary>
25351 </indexterm>
25352 <function>pg_has_role</function> (
25353 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
25354 <parameter>role</parameter> <type>text</type> or <type>oid</type>,
25355 <parameter>privilege</parameter> <type>text</type> )
25356 <returnvalue>boolean</returnvalue>
25357 </para>
25358 <para>
25359 Does user have privilege for role?
25360 Allowable privilege types are
25361 <literal>MEMBER</literal>, <literal>USAGE</literal>,
25362 and <literal>SET</literal>.
25363 <literal>MEMBER</literal> denotes direct or indirect membership in
25364 the role without regard to what specific privileges may be conferred.
25365 <literal>USAGE</literal> denotes whether the privileges of the role
25366 are immediately available without doing <command>SET ROLE</command>,
25367 while <literal>SET</literal> denotes whether it is possible to change
25368 to the role using the <literal>SET ROLE</literal> command.
25369 <literal>WITH ADMIN OPTION</literal> or <literal>WITH GRANT
25370 OPTION</literal> can be added to any of these privilege types to
25371 test whether the <literal>ADMIN</literal> privilege is held (all
25372 six spellings test the same thing).
25373 This function does not allow the special case of
25374 setting <parameter>user</parameter> to <literal>public</literal>,
25375 because the PUBLIC pseudo-role can never be a member of real roles.
25376 </para></entry>
25377 </row>
25379 <row>
25380 <entry role="func_table_entry"><para role="func_signature">
25381 <indexterm>
25382 <primary>row_security_active</primary>
25383 </indexterm>
25384 <function>row_security_active</function> (
25385 <parameter>table</parameter> <type>text</type> or <type>oid</type> )
25386 <returnvalue>boolean</returnvalue>
25387 </para>
25388 <para>
25389 Is row-level security active for the specified table in the context of
25390 the current user and current environment?
25391 </para></entry>
25392 </row>
25393 </tbody>
25394 </tgroup>
25395 </table>
25397 <para>
25398 <xref linkend="functions-aclitem-op-table"/> shows the operators
25399 available for the <type>aclitem</type> type, which is the catalog
25400 representation of access privileges. See <xref linkend="ddl-priv"/>
25401 for information about how to read access privilege values.
25402 </para>
25404 <table id="functions-aclitem-op-table">
25405 <title><type>aclitem</type> Operators</title>
25406 <tgroup cols="1">
25407 <thead>
25408 <row>
25409 <entry role="func_table_entry"><para role="func_signature">
25410 Operator
25411 </para>
25412 <para>
25413 Description
25414 </para>
25415 <para>
25416 Example(s)
25417 </para></entry>
25418 </row>
25419 </thead>
25421 <tbody>
25422 <row>
25423 <entry role="func_table_entry"><para role="func_signature">
25424 <indexterm>
25425 <primary>aclitemeq</primary>
25426 </indexterm>
25427 <type>aclitem</type> <literal>=</literal> <type>aclitem</type>
25428 <returnvalue>boolean</returnvalue>
25429 </para>
25430 <para>
25431 Are <type>aclitem</type>s equal? (Notice that
25432 type <type>aclitem</type> lacks the usual set of comparison
25433 operators; it has only equality. In turn, <type>aclitem</type>
25434 arrays can only be compared for equality.)
25435 </para>
25436 <para>
25437 <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem</literal>
25438 <returnvalue>f</returnvalue>
25439 </para></entry>
25440 </row>
25442 <row>
25443 <entry role="func_table_entry"><para role="func_signature">
25444 <indexterm>
25445 <primary>aclcontains</primary>
25446 </indexterm>
25447 <type>aclitem[]</type> <literal>@&gt;</literal> <type>aclitem</type>
25448 <returnvalue>boolean</returnvalue>
25449 </para>
25450 <para>
25451 Does array contain the specified privileges? (This is true if there
25452 is an array entry that matches the <type>aclitem</type>'s grantee and
25453 grantor, and has at least the specified set of privileges.)
25454 </para>
25455 <para>
25456 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @&gt; 'calvin=r*/hobbes'::aclitem</literal>
25457 <returnvalue>t</returnvalue>
25458 </para></entry>
25459 </row>
25461 <row>
25462 <entry role="func_table_entry"><para role="func_signature">
25463 <type>aclitem[]</type> <literal>~</literal> <type>aclitem</type>
25464 <returnvalue>boolean</returnvalue>
25465 </para>
25466 <para>
25467 This is a deprecated alias for <literal>@&gt;</literal>.
25468 </para>
25469 <para>
25470 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem</literal>
25471 <returnvalue>t</returnvalue>
25472 </para></entry>
25473 </row>
25474 </tbody>
25475 </tgroup>
25476 </table>
25478 <para>
25479 <xref linkend="functions-aclitem-fn-table"/> shows some additional
25480 functions to manage the <type>aclitem</type> type.
25481 </para>
25483 <table id="functions-aclitem-fn-table">
25484 <title><type>aclitem</type> Functions</title>
25485 <tgroup cols="1">
25486 <thead>
25487 <row>
25488 <entry role="func_table_entry"><para role="func_signature">
25489 Function
25490 </para>
25491 <para>
25492 Description
25493 </para></entry>
25494 </row>
25495 </thead>
25497 <tbody>
25498 <row>
25499 <entry role="func_table_entry"><para role="func_signature">
25500 <indexterm>
25501 <primary>acldefault</primary>
25502 </indexterm>
25503 <function>acldefault</function> (
25504 <parameter>type</parameter> <type>"char"</type>,
25505 <parameter>ownerId</parameter> <type>oid</type> )
25506 <returnvalue>aclitem[]</returnvalue>
25507 </para>
25508 <para>
25509 Constructs an <type>aclitem</type> array holding the default access
25510 privileges for an object of type <parameter>type</parameter> belonging
25511 to the role with OID <parameter>ownerId</parameter>. This represents
25512 the access privileges that will be assumed when an object's
25513 <acronym>ACL</acronym> entry is null. (The default access privileges
25514 are described in <xref linkend="ddl-priv"/>.)
25515 The <parameter>type</parameter> parameter must be one of
25516 'c' for <literal>COLUMN</literal>,
25517 'r' for <literal>TABLE</literal> and table-like objects,
25518 's' for <literal>SEQUENCE</literal>,
25519 'd' for <literal>DATABASE</literal>,
25520 'f' for <literal>FUNCTION</literal> or <literal>PROCEDURE</literal>,
25521 'l' for <literal>LANGUAGE</literal>,
25522 'L' for <literal>LARGE OBJECT</literal>,
25523 'n' for <literal>SCHEMA</literal>,
25524 'p' for <literal>PARAMETER</literal>,
25525 't' for <literal>TABLESPACE</literal>,
25526 'F' for <literal>FOREIGN DATA WRAPPER</literal>,
25527 'S' for <literal>FOREIGN SERVER</literal>,
25529 'T' for <literal>TYPE</literal> or <literal>DOMAIN</literal>.
25530 </para></entry>
25531 </row>
25533 <row>
25534 <entry role="func_table_entry"><para role="func_signature">
25535 <indexterm>
25536 <primary>aclexplode</primary>
25537 </indexterm>
25538 <function>aclexplode</function> ( <type>aclitem[]</type> )
25539 <returnvalue>setof record</returnvalue>
25540 ( <parameter>grantor</parameter> <type>oid</type>,
25541 <parameter>grantee</parameter> <type>oid</type>,
25542 <parameter>privilege_type</parameter> <type>text</type>,
25543 <parameter>is_grantable</parameter> <type>boolean</type> )
25544 </para>
25545 <para>
25546 Returns the <type>aclitem</type> array as a set of rows.
25547 If the grantee is the pseudo-role PUBLIC, it is represented by zero in
25548 the <parameter>grantee</parameter> column. Each granted privilege is
25549 represented as <literal>SELECT</literal>, <literal>INSERT</literal>,
25550 etc (see <xref linkend="privilege-abbrevs-table"/> for a full list).
25551 Note that each privilege is broken out as a separate row, so
25552 only one keyword appears in the <parameter>privilege_type</parameter>
25553 column.
25554 </para></entry>
25555 </row>
25557 <row>
25558 <entry role="func_table_entry"><para role="func_signature">
25559 <indexterm>
25560 <primary>makeaclitem</primary>
25561 </indexterm>
25562 <function>makeaclitem</function> (
25563 <parameter>grantee</parameter> <type>oid</type>,
25564 <parameter>grantor</parameter> <type>oid</type>,
25565 <parameter>privileges</parameter> <type>text</type>,
25566 <parameter>is_grantable</parameter> <type>boolean</type> )
25567 <returnvalue>aclitem</returnvalue>
25568 </para>
25569 <para>
25570 Constructs an <type>aclitem</type> with the given properties.
25571 <parameter>privileges</parameter> is a comma-separated list of
25572 privilege names such as <literal>SELECT</literal>,
25573 <literal>INSERT</literal>, etc, all of which are set in the
25574 result. (Case of the privilege string is not significant, and
25575 extra whitespace is allowed between but not within privilege
25576 names.)
25577 </para></entry>
25578 </row>
25579 </tbody>
25580 </tgroup>
25581 </table>
25583 </sect2>
25585 <sect2 id="functions-info-schema">
25586 <title>Schema Visibility Inquiry Functions</title>
25588 <para>
25589 <xref linkend="functions-info-schema-table"/> shows functions that
25590 determine whether a certain object is <firstterm>visible</firstterm> in the
25591 current schema search path.
25592 For example, a table is said to be visible if its
25593 containing schema is in the search path and no table of the same
25594 name appears earlier in the search path. This is equivalent to the
25595 statement that the table can be referenced by name without explicit
25596 schema qualification. Thus, to list the names of all visible tables:
25597 <programlisting>
25598 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
25599 </programlisting>
25600 For functions and operators, an object in the search path is said to be
25601 visible if there is no object of the same name <emphasis>and argument data
25602 type(s)</emphasis> earlier in the path. For operator classes and families,
25603 both the name and the associated index access method are considered.
25604 </para>
25606 <indexterm>
25607 <primary>search path</primary>
25608 <secondary>object visibility</secondary>
25609 </indexterm>
25611 <table id="functions-info-schema-table">
25612 <title>Schema Visibility Inquiry Functions</title>
25613 <tgroup cols="1">
25614 <thead>
25615 <row>
25616 <entry role="func_table_entry"><para role="func_signature">
25617 Function
25618 </para>
25619 <para>
25620 Description
25621 </para></entry>
25622 </row>
25623 </thead>
25625 <tbody>
25626 <row>
25627 <entry role="func_table_entry"><para role="func_signature">
25628 <indexterm>
25629 <primary>pg_collation_is_visible</primary>
25630 </indexterm>
25631 <function>pg_collation_is_visible</function> ( <parameter>collation</parameter> <type>oid</type> )
25632 <returnvalue>boolean</returnvalue>
25633 </para>
25634 <para>
25635 Is collation visible in search path?
25636 </para></entry>
25637 </row>
25639 <row>
25640 <entry role="func_table_entry"><para role="func_signature">
25641 <indexterm>
25642 <primary>pg_conversion_is_visible</primary>
25643 </indexterm>
25644 <function>pg_conversion_is_visible</function> ( <parameter>conversion</parameter> <type>oid</type> )
25645 <returnvalue>boolean</returnvalue>
25646 </para>
25647 <para>
25648 Is conversion visible in search path?
25649 </para></entry>
25650 </row>
25652 <row>
25653 <entry role="func_table_entry"><para role="func_signature">
25654 <indexterm>
25655 <primary>pg_function_is_visible</primary>
25656 </indexterm>
25657 <function>pg_function_is_visible</function> ( <parameter>function</parameter> <type>oid</type> )
25658 <returnvalue>boolean</returnvalue>
25659 </para>
25660 <para>
25661 Is function visible in search path?
25662 (This also works for procedures and aggregates.)
25663 </para></entry>
25664 </row>
25666 <row>
25667 <entry role="func_table_entry"><para role="func_signature">
25668 <indexterm>
25669 <primary>pg_opclass_is_visible</primary>
25670 </indexterm>
25671 <function>pg_opclass_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
25672 <returnvalue>boolean</returnvalue>
25673 </para>
25674 <para>
25675 Is operator class visible in search path?
25676 </para></entry>
25677 </row>
25679 <row>
25680 <entry role="func_table_entry"><para role="func_signature">
25681 <indexterm>
25682 <primary>pg_operator_is_visible</primary>
25683 </indexterm>
25684 <function>pg_operator_is_visible</function> ( <parameter>operator</parameter> <type>oid</type> )
25685 <returnvalue>boolean</returnvalue>
25686 </para>
25687 <para>
25688 Is operator visible in search path?
25689 </para></entry>
25690 </row>
25692 <row>
25693 <entry role="func_table_entry"><para role="func_signature">
25694 <indexterm>
25695 <primary>pg_opfamily_is_visible</primary>
25696 </indexterm>
25697 <function>pg_opfamily_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
25698 <returnvalue>boolean</returnvalue>
25699 </para>
25700 <para>
25701 Is operator family visible in search path?
25702 </para></entry>
25703 </row>
25705 <row>
25706 <entry role="func_table_entry"><para role="func_signature">
25707 <indexterm>
25708 <primary>pg_statistics_obj_is_visible</primary>
25709 </indexterm>
25710 <function>pg_statistics_obj_is_visible</function> ( <parameter>stat</parameter> <type>oid</type> )
25711 <returnvalue>boolean</returnvalue>
25712 </para>
25713 <para>
25714 Is statistics object visible in search path?
25715 </para></entry>
25716 </row>
25718 <row>
25719 <entry role="func_table_entry"><para role="func_signature">
25720 <indexterm>
25721 <primary>pg_table_is_visible</primary>
25722 </indexterm>
25723 <function>pg_table_is_visible</function> ( <parameter>table</parameter> <type>oid</type> )
25724 <returnvalue>boolean</returnvalue>
25725 </para>
25726 <para>
25727 Is table visible in search path?
25728 (This works for all types of relations, including views, materialized
25729 views, indexes, sequences and foreign tables.)
25730 </para></entry>
25731 </row>
25733 <row>
25734 <entry role="func_table_entry"><para role="func_signature">
25735 <indexterm>
25736 <primary>pg_ts_config_is_visible</primary>
25737 </indexterm>
25738 <function>pg_ts_config_is_visible</function> ( <parameter>config</parameter> <type>oid</type> )
25739 <returnvalue>boolean</returnvalue>
25740 </para>
25741 <para>
25742 Is text search configuration visible in search path?
25743 </para></entry>
25744 </row>
25746 <row>
25747 <entry role="func_table_entry"><para role="func_signature">
25748 <indexterm>
25749 <primary>pg_ts_dict_is_visible</primary>
25750 </indexterm>
25751 <function>pg_ts_dict_is_visible</function> ( <parameter>dict</parameter> <type>oid</type> )
25752 <returnvalue>boolean</returnvalue>
25753 </para>
25754 <para>
25755 Is text search dictionary visible in search path?
25756 </para></entry>
25757 </row>
25759 <row>
25760 <entry role="func_table_entry"><para role="func_signature">
25761 <indexterm>
25762 <primary>pg_ts_parser_is_visible</primary>
25763 </indexterm>
25764 <function>pg_ts_parser_is_visible</function> ( <parameter>parser</parameter> <type>oid</type> )
25765 <returnvalue>boolean</returnvalue>
25766 </para>
25767 <para>
25768 Is text search parser visible in search path?
25769 </para></entry>
25770 </row>
25772 <row>
25773 <entry role="func_table_entry"><para role="func_signature">
25774 <indexterm>
25775 <primary>pg_ts_template_is_visible</primary>
25776 </indexterm>
25777 <function>pg_ts_template_is_visible</function> ( <parameter>template</parameter> <type>oid</type> )
25778 <returnvalue>boolean</returnvalue>
25779 </para>
25780 <para>
25781 Is text search template visible in search path?
25782 </para></entry>
25783 </row>
25785 <row>
25786 <entry role="func_table_entry"><para role="func_signature">
25787 <indexterm>
25788 <primary>pg_type_is_visible</primary>
25789 </indexterm>
25790 <function>pg_type_is_visible</function> ( <parameter>type</parameter> <type>oid</type> )
25791 <returnvalue>boolean</returnvalue>
25792 </para>
25793 <para>
25794 Is type (or domain) visible in search path?
25795 </para></entry>
25796 </row>
25797 </tbody>
25798 </tgroup>
25799 </table>
25801 <para>
25802 All these functions require object OIDs to identify the object to be
25803 checked. If you want to test an object by name, it is convenient to use
25804 the OID alias types (<type>regclass</type>, <type>regtype</type>,
25805 <type>regprocedure</type>, <type>regoperator</type>, <type>regconfig</type>,
25806 or <type>regdictionary</type>),
25807 for example:
25808 <programlisting>
25809 SELECT pg_type_is_visible('myschema.widget'::regtype);
25810 </programlisting>
25811 Note that it would not make much sense to test a non-schema-qualified
25812 type name in this way &mdash; if the name can be recognized at all, it must be visible.
25813 </para>
25815 </sect2>
25817 <sect2 id="functions-info-catalog">
25818 <title>System Catalog Information Functions</title>
25820 <para>
25821 <xref linkend="functions-info-catalog-table"/> lists functions that
25822 extract information from the system catalogs.
25823 </para>
25825 <table id="functions-info-catalog-table">
25826 <title>System Catalog Information Functions</title>
25827 <tgroup cols="1">
25828 <thead>
25829 <row>
25830 <entry role="func_table_entry"><para role="func_signature">
25831 Function
25832 </para>
25833 <para>
25834 Description
25835 </para></entry>
25836 </row>
25837 </thead>
25839 <tbody>
25840 <row>
25841 <entry id="format-type" xreflabel="format_type" role="func_table_entry"><para role="func_signature">
25842 <indexterm>
25843 <primary>format_type</primary>
25844 </indexterm>
25845 <function>format_type</function> ( <parameter>type</parameter> <type>oid</type>, <parameter>typemod</parameter> <type>integer</type> )
25846 <returnvalue>text</returnvalue>
25847 </para>
25848 <para>
25849 Returns the SQL name for a data type that is identified by its type
25850 OID and possibly a type modifier. Pass NULL for the type modifier if
25851 no specific modifier is known.
25852 </para></entry>
25853 </row>
25855 <row>
25856 <entry role="func_table_entry"><para role="func_signature">
25857 <indexterm>
25858 <primary>pg_basetype</primary>
25859 </indexterm>
25860 <function>pg_basetype</function> ( <type>regtype</type> )
25861 <returnvalue>regtype</returnvalue>
25862 </para>
25863 <para>
25864 Returns the OID of the base type of a domain identified by its
25865 type OID. If the argument is the OID of a non-domain type,
25866 returns the argument as-is. Returns NULL if the argument is
25867 not a valid type OID. If there's a chain of domain dependencies,
25868 it will recurse until finding the base type.
25869 </para>
25870 <para>
25871 Assuming <literal>CREATE DOMAIN mytext AS text</literal>:
25872 </para>
25873 <para>
25874 <literal>pg_basetype('mytext'::regtype)</literal>
25875 <returnvalue>text</returnvalue>
25876 </para></entry>
25877 </row>
25879 <row>
25880 <entry id="pg-char-to-encoding" role="func_table_entry"><para role="func_signature">
25881 <indexterm>
25882 <primary>pg_char_to_encoding</primary>
25883 </indexterm>
25884 <function>pg_char_to_encoding</function> ( <parameter>encoding</parameter> <type>name</type> )
25885 <returnvalue>integer</returnvalue>
25886 </para>
25887 <para>
25888 Converts the supplied encoding name into an integer representing the
25889 internal identifier used in some system catalog tables.
25890 Returns <literal>-1</literal> if an unknown encoding name is provided.
25891 </para></entry>
25892 </row>
25894 <row>
25895 <entry id="pg-encoding-to-char" role="func_table_entry"><para role="func_signature">
25896 <indexterm>
25897 <primary>pg_encoding_to_char</primary>
25898 </indexterm>
25899 <function>pg_encoding_to_char</function> ( <parameter>encoding</parameter> <type>integer</type> )
25900 <returnvalue>name</returnvalue>
25901 </para>
25902 <para>
25903 Converts the integer used as the internal identifier of an encoding in some
25904 system catalog tables into a human-readable string.
25905 Returns an empty string if an invalid encoding number is provided.
25906 </para></entry>
25907 </row>
25909 <row>
25910 <entry role="func_table_entry"><para role="func_signature">
25911 <indexterm>
25912 <primary>pg_get_catalog_foreign_keys</primary>
25913 </indexterm>
25914 <function>pg_get_catalog_foreign_keys</function> ()
25915 <returnvalue>setof record</returnvalue>
25916 ( <parameter>fktable</parameter> <type>regclass</type>,
25917 <parameter>fkcols</parameter> <type>text[]</type>,
25918 <parameter>pktable</parameter> <type>regclass</type>,
25919 <parameter>pkcols</parameter> <type>text[]</type>,
25920 <parameter>is_array</parameter> <type>boolean</type>,
25921 <parameter>is_opt</parameter> <type>boolean</type> )
25922 </para>
25923 <para>
25924 Returns a set of records describing the foreign key relationships
25925 that exist within the <productname>PostgreSQL</productname> system
25926 catalogs.
25927 The <parameter>fktable</parameter> column contains the name of the
25928 referencing catalog, and the <parameter>fkcols</parameter> column
25929 contains the name(s) of the referencing column(s). Similarly,
25930 the <parameter>pktable</parameter> column contains the name of the
25931 referenced catalog, and the <parameter>pkcols</parameter> column
25932 contains the name(s) of the referenced column(s).
25933 If <parameter>is_array</parameter> is true, the last referencing
25934 column is an array, each of whose elements should match some entry
25935 in the referenced catalog.
25936 If <parameter>is_opt</parameter> is true, the referencing column(s)
25937 are allowed to contain zeroes instead of a valid reference.
25938 </para></entry>
25939 </row>
25941 <row>
25942 <entry role="func_table_entry"><para role="func_signature">
25943 <indexterm>
25944 <primary>pg_get_constraintdef</primary>
25945 </indexterm>
25946 <function>pg_get_constraintdef</function> ( <parameter>constraint</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
25947 <returnvalue>text</returnvalue>
25948 </para>
25949 <para>
25950 Reconstructs the creating command for a constraint.
25951 (This is a decompiled reconstruction, not the original text
25952 of the command.)
25953 </para></entry>
25954 </row>
25956 <row>
25957 <entry role="func_table_entry"><para role="func_signature">
25958 <indexterm>
25959 <primary>pg_get_expr</primary>
25960 </indexterm>
25961 <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> )
25962 <returnvalue>text</returnvalue>
25963 </para>
25964 <para>
25965 Decompiles the internal form of an expression stored in the system
25966 catalogs, such as the default value for a column. If the expression
25967 might contain Vars, specify the OID of the relation they refer to as
25968 the second parameter; if no Vars are expected, passing zero is
25969 sufficient.
25970 </para></entry>
25971 </row>
25973 <row>
25974 <entry role="func_table_entry"><para role="func_signature">
25975 <indexterm>
25976 <primary>pg_get_functiondef</primary>
25977 </indexterm>
25978 <function>pg_get_functiondef</function> ( <parameter>func</parameter> <type>oid</type> )
25979 <returnvalue>text</returnvalue>
25980 </para>
25981 <para>
25982 Reconstructs the creating command for a function or procedure.
25983 (This is a decompiled reconstruction, not the original text
25984 of the command.)
25985 The result is a complete <command>CREATE OR REPLACE FUNCTION</command>
25986 or <command>CREATE OR REPLACE PROCEDURE</command> statement.
25987 </para></entry>
25988 </row>
25990 <row>
25991 <entry role="func_table_entry"><para role="func_signature">
25992 <indexterm>
25993 <primary>pg_get_function_arguments</primary>
25994 </indexterm>
25995 <function>pg_get_function_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
25996 <returnvalue>text</returnvalue>
25997 </para>
25998 <para>
25999 Reconstructs the argument list of a function or procedure, in the form
26000 it would need to appear in within <command>CREATE FUNCTION</command>
26001 (including default values).
26002 </para></entry>
26003 </row>
26005 <row>
26006 <entry role="func_table_entry"><para role="func_signature">
26007 <indexterm>
26008 <primary>pg_get_function_identity_arguments</primary>
26009 </indexterm>
26010 <function>pg_get_function_identity_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
26011 <returnvalue>text</returnvalue>
26012 </para>
26013 <para>
26014 Reconstructs the argument list necessary to identify a function or
26015 procedure, in the form it would need to appear in within commands such
26016 as <command>ALTER FUNCTION</command>. This form omits default values.
26017 </para></entry>
26018 </row>
26020 <row>
26021 <entry role="func_table_entry"><para role="func_signature">
26022 <indexterm>
26023 <primary>pg_get_function_result</primary>
26024 </indexterm>
26025 <function>pg_get_function_result</function> ( <parameter>func</parameter> <type>oid</type> )
26026 <returnvalue>text</returnvalue>
26027 </para>
26028 <para>
26029 Reconstructs the <literal>RETURNS</literal> clause of a function, in
26030 the form it would need to appear in within <command>CREATE
26031 FUNCTION</command>. Returns <literal>NULL</literal> for a procedure.
26032 </para></entry>
26033 </row>
26035 <row>
26036 <entry role="func_table_entry"><para role="func_signature">
26037 <indexterm>
26038 <primary>pg_get_indexdef</primary>
26039 </indexterm>
26040 <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> )
26041 <returnvalue>text</returnvalue>
26042 </para>
26043 <para>
26044 Reconstructs the creating command for an index.
26045 (This is a decompiled reconstruction, not the original text
26046 of the command.) If <parameter>column</parameter> is supplied and is
26047 not zero, only the definition of that column is reconstructed.
26048 </para></entry>
26049 </row>
26051 <row>
26052 <entry role="func_table_entry"><para role="func_signature">
26053 <indexterm>
26054 <primary>pg_get_keywords</primary>
26055 </indexterm>
26056 <function>pg_get_keywords</function> ()
26057 <returnvalue>setof record</returnvalue>
26058 ( <parameter>word</parameter> <type>text</type>,
26059 <parameter>catcode</parameter> <type>"char"</type>,
26060 <parameter>barelabel</parameter> <type>boolean</type>,
26061 <parameter>catdesc</parameter> <type>text</type>,
26062 <parameter>baredesc</parameter> <type>text</type> )
26063 </para>
26064 <para>
26065 Returns a set of records describing the SQL keywords recognized by the
26066 server. The <parameter>word</parameter> column contains the
26067 keyword. The <parameter>catcode</parameter> column contains a
26068 category code: <literal>U</literal> for an unreserved
26069 keyword, <literal>C</literal> for a keyword that can be a column
26070 name, <literal>T</literal> for a keyword that can be a type or
26071 function name, or <literal>R</literal> for a fully reserved keyword.
26072 The <parameter>barelabel</parameter> column
26073 contains <literal>true</literal> if the keyword can be used as
26074 a <quote>bare</quote> column label in <command>SELECT</command> lists,
26075 or <literal>false</literal> if it can only be used
26076 after <literal>AS</literal>.
26077 The <parameter>catdesc</parameter> column contains a
26078 possibly-localized string describing the keyword's category.
26079 The <parameter>baredesc</parameter> column contains a
26080 possibly-localized string describing the keyword's column label status.
26081 </para></entry>
26082 </row>
26084 <row>
26085 <entry role="func_table_entry"><para role="func_signature">
26086 <indexterm>
26087 <primary>pg_get_partkeydef</primary>
26088 </indexterm>
26089 <function>pg_get_partkeydef</function> ( <parameter>table</parameter> <type>oid</type> )
26090 <returnvalue>text</returnvalue>
26091 </para>
26092 <para>
26093 Reconstructs the definition of a partitioned table's partition
26094 key, in the form it would have in the <literal>PARTITION
26095 BY</literal> clause of <command>CREATE TABLE</command>.
26096 (This is a decompiled reconstruction, not the original text
26097 of the command.)
26098 </para></entry>
26099 </row>
26101 <row>
26102 <entry role="func_table_entry"><para role="func_signature">
26103 <indexterm>
26104 <primary>pg_get_ruledef</primary>
26105 </indexterm>
26106 <function>pg_get_ruledef</function> ( <parameter>rule</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
26107 <returnvalue>text</returnvalue>
26108 </para>
26109 <para>
26110 Reconstructs the creating command for a rule.
26111 (This is a decompiled reconstruction, not the original text
26112 of the command.)
26113 </para></entry>
26114 </row>
26116 <row>
26117 <entry role="func_table_entry"><para role="func_signature">
26118 <indexterm>
26119 <primary>pg_get_serial_sequence</primary>
26120 </indexterm>
26121 <function>pg_get_serial_sequence</function> ( <parameter>table</parameter> <type>text</type>, <parameter>column</parameter> <type>text</type> )
26122 <returnvalue>text</returnvalue>
26123 </para>
26124 <para>
26125 Returns the name of the sequence associated with a column,
26126 or NULL if no sequence is associated with the column.
26127 If the column is an identity column, the associated sequence is the
26128 sequence internally created for that column.
26129 For columns created using one of the serial types
26130 (<type>serial</type>, <type>smallserial</type>, <type>bigserial</type>),
26131 it is the sequence created for that serial column definition.
26132 In the latter case, the association can be modified or removed
26133 with <command>ALTER SEQUENCE OWNED BY</command>.
26134 (This function probably should have been
26135 called <function>pg_get_owned_sequence</function>; its current name
26136 reflects the fact that it has historically been used with serial-type
26137 columns.) The first parameter is a table name with optional
26138 schema, and the second parameter is a column name. Because the first
26139 parameter potentially contains both schema and table names, it is
26140 parsed per usual SQL rules, meaning it is lower-cased by default.
26141 The second parameter, being just a column name, is treated literally
26142 and so has its case preserved. The result is suitably formatted
26143 for passing to the sequence functions (see
26144 <xref linkend="functions-sequence"/>).
26145 </para>
26146 <para>
26147 A typical use is in reading the current value of the sequence for an
26148 identity or serial column, for example:
26149 <programlisting>
26150 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
26151 </programlisting>
26152 </para></entry>
26153 </row>
26155 <row>
26156 <entry role="func_table_entry"><para role="func_signature">
26157 <indexterm>
26158 <primary>pg_get_statisticsobjdef</primary>
26159 </indexterm>
26160 <function>pg_get_statisticsobjdef</function> ( <parameter>statobj</parameter> <type>oid</type> )
26161 <returnvalue>text</returnvalue>
26162 </para>
26163 <para>
26164 Reconstructs the creating command for an extended statistics object.
26165 (This is a decompiled reconstruction, not the original text
26166 of the command.)
26167 </para></entry>
26168 </row>
26170 <row>
26171 <entry role="func_table_entry"><para role="func_signature">
26172 <indexterm>
26173 <primary>pg_get_triggerdef</primary>
26174 </indexterm>
26175 <function>pg_get_triggerdef</function> ( <parameter>trigger</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
26176 <returnvalue>text</returnvalue>
26177 </para>
26178 <para>
26179 Reconstructs the creating command for a trigger.
26180 (This is a decompiled reconstruction, not the original text
26181 of the command.)
26182 </para></entry>
26183 </row>
26185 <row>
26186 <entry role="func_table_entry"><para role="func_signature">
26187 <indexterm>
26188 <primary>pg_get_userbyid</primary>
26189 </indexterm>
26190 <function>pg_get_userbyid</function> ( <parameter>role</parameter> <type>oid</type> )
26191 <returnvalue>name</returnvalue>
26192 </para>
26193 <para>
26194 Returns a role's name given its OID.
26195 </para></entry>
26196 </row>
26198 <row>
26199 <entry role="func_table_entry"><para role="func_signature">
26200 <indexterm>
26201 <primary>pg_get_viewdef</primary>
26202 </indexterm>
26203 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
26204 <returnvalue>text</returnvalue>
26205 </para>
26206 <para>
26207 Reconstructs the underlying <command>SELECT</command> command for a
26208 view or materialized view. (This is a decompiled reconstruction, not
26209 the original text of the command.)
26210 </para></entry>
26211 </row>
26213 <row>
26214 <entry role="func_table_entry"><para role="func_signature">
26215 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type>, <parameter>wrap_column</parameter> <type>integer</type> )
26216 <returnvalue>text</returnvalue>
26217 </para>
26218 <para>
26219 Reconstructs the underlying <command>SELECT</command> command for a
26220 view or materialized view. (This is a decompiled reconstruction, not
26221 the original text of the command.) In this form of the function,
26222 pretty-printing is always enabled, and long lines are wrapped to try
26223 to keep them shorter than the specified number of columns.
26224 </para></entry>
26225 </row>
26227 <row>
26228 <entry role="func_table_entry"><para role="func_signature">
26229 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>text</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
26230 <returnvalue>text</returnvalue>
26231 </para>
26232 <para>
26233 Reconstructs the underlying <command>SELECT</command> command for a
26234 view or materialized view, working from a textual name for the view
26235 rather than its OID. (This is deprecated; use the OID variant
26236 instead.)
26237 </para></entry>
26238 </row>
26240 <row>
26241 <entry role="func_table_entry"><para role="func_signature">
26242 <indexterm>
26243 <primary>pg_index_column_has_property</primary>
26244 </indexterm>
26245 <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> )
26246 <returnvalue>boolean</returnvalue>
26247 </para>
26248 <para>
26249 Tests whether an index column has the named property.
26250 Common index column properties are listed in
26251 <xref linkend="functions-info-index-column-props"/>.
26252 (Note that extension access methods can define additional property
26253 names for their indexes.)
26254 <literal>NULL</literal> is returned if the property name is not known
26255 or does not apply to the particular object, or if the OID or column
26256 number does not identify a valid object.
26257 </para></entry>
26258 </row>
26260 <row>
26261 <entry role="func_table_entry"><para role="func_signature">
26262 <indexterm>
26263 <primary>pg_index_has_property</primary>
26264 </indexterm>
26265 <function>pg_index_has_property</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>property</parameter> <type>text</type> )
26266 <returnvalue>boolean</returnvalue>
26267 </para>
26268 <para>
26269 Tests whether an index has the named property.
26270 Common index properties are listed in
26271 <xref linkend="functions-info-index-props"/>.
26272 (Note that extension access methods can define additional property
26273 names for their indexes.)
26274 <literal>NULL</literal> is returned if the property name is not known
26275 or does not apply to the particular object, or if the OID does not
26276 identify a valid object.
26277 </para></entry>
26278 </row>
26280 <row>
26281 <entry role="func_table_entry"><para role="func_signature">
26282 <indexterm>
26283 <primary>pg_indexam_has_property</primary>
26284 </indexterm>
26285 <function>pg_indexam_has_property</function> ( <parameter>am</parameter> <type>oid</type>, <parameter>property</parameter> <type>text</type> )
26286 <returnvalue>boolean</returnvalue>
26287 </para>
26288 <para>
26289 Tests whether an index access method has the named property.
26290 Access method properties are listed in
26291 <xref linkend="functions-info-indexam-props"/>.
26292 <literal>NULL</literal> is returned if the property name is not known
26293 or does not apply to the particular object, or if the OID does not
26294 identify a valid object.
26295 </para></entry>
26296 </row>
26298 <row>
26299 <entry role="func_table_entry"><para role="func_signature">
26300 <indexterm>
26301 <primary>pg_options_to_table</primary>
26302 </indexterm>
26303 <function>pg_options_to_table</function> ( <parameter>options_array</parameter> <type>text[]</type> )
26304 <returnvalue>setof record</returnvalue>
26305 ( <parameter>option_name</parameter> <type>text</type>,
26306 <parameter>option_value</parameter> <type>text</type> )
26307 </para>
26308 <para>
26309 Returns the set of storage options represented by a value from
26310 <structname>pg_class</structname>.<structfield>reloptions</structfield> or
26311 <structname>pg_attribute</structname>.<structfield>attoptions</structfield>.
26312 </para></entry>
26313 </row>
26315 <row>
26316 <entry role="func_table_entry"><para role="func_signature">
26317 <indexterm>
26318 <primary>pg_settings_get_flags</primary>
26319 </indexterm>
26320 <function>pg_settings_get_flags</function> ( <parameter>guc</parameter> <type>text</type> )
26321 <returnvalue>text[]</returnvalue>
26322 </para>
26323 <para>
26324 Returns an array of the flags associated with the given GUC, or
26325 <literal>NULL</literal> if it does not exist. The result is
26326 an empty array if the GUC exists but there are no flags to show.
26327 Only the most useful flags listed in
26328 <xref linkend="functions-pg-settings-flags"/> are exposed.
26329 </para></entry>
26330 </row>
26332 <row>
26333 <entry role="func_table_entry"><para role="func_signature">
26334 <indexterm>
26335 <primary>pg_tablespace_databases</primary>
26336 </indexterm>
26337 <function>pg_tablespace_databases</function> ( <parameter>tablespace</parameter> <type>oid</type> )
26338 <returnvalue>setof oid</returnvalue>
26339 </para>
26340 <para>
26341 Returns the set of OIDs of databases that have objects stored in the
26342 specified tablespace. If this function returns any rows, the
26343 tablespace is not empty and cannot be dropped. To identify the specific
26344 objects populating the tablespace, you will need to connect to the
26345 database(s) identified by <function>pg_tablespace_databases</function>
26346 and query their <structname>pg_class</structname> catalogs.
26347 </para></entry>
26348 </row>
26350 <row>
26351 <entry role="func_table_entry"><para role="func_signature">
26352 <indexterm>
26353 <primary>pg_tablespace_location</primary>
26354 </indexterm>
26355 <function>pg_tablespace_location</function> ( <parameter>tablespace</parameter> <type>oid</type> )
26356 <returnvalue>text</returnvalue>
26357 </para>
26358 <para>
26359 Returns the file system path that this tablespace is located in.
26360 </para></entry>
26361 </row>
26363 <row>
26364 <entry role="func_table_entry"><para role="func_signature">
26365 <indexterm>
26366 <primary>pg_typeof</primary>
26367 </indexterm>
26368 <function>pg_typeof</function> ( <type>"any"</type> )
26369 <returnvalue>regtype</returnvalue>
26370 </para>
26371 <para>
26372 Returns the OID of the data type of the value that is passed to it.
26373 This can be helpful for troubleshooting or dynamically constructing
26374 SQL queries. The function is declared as
26375 returning <type>regtype</type>, which is an OID alias type (see
26376 <xref linkend="datatype-oid"/>); this means that it is the same as an
26377 OID for comparison purposes but displays as a type name.
26378 </para>
26379 <para>
26380 <literal>pg_typeof(33)</literal>
26381 <returnvalue>integer</returnvalue>
26382 </para></entry>
26383 </row>
26385 <row>
26386 <entry role="func_table_entry"><para role="func_signature">
26387 <indexterm>
26388 <primary>COLLATION FOR</primary>
26389 </indexterm>
26390 <function>COLLATION FOR</function> ( <type>"any"</type> )
26391 <returnvalue>text</returnvalue>
26392 </para>
26393 <para>
26394 Returns the name of the collation of the value that is passed to it.
26395 The value is quoted and schema-qualified if necessary. If no
26396 collation was derived for the argument expression,
26397 then <literal>NULL</literal> is returned. If the argument is not of a
26398 collatable data type, then an error is raised.
26399 </para>
26400 <para>
26401 <literal>collation for ('foo'::text)</literal>
26402 <returnvalue>"default"</returnvalue>
26403 </para>
26404 <para>
26405 <literal>collation for ('foo' COLLATE "de_DE")</literal>
26406 <returnvalue>"de_DE"</returnvalue>
26407 </para></entry>
26408 </row>
26410 <row>
26411 <entry role="func_table_entry"><para role="func_signature">
26412 <indexterm>
26413 <primary>to_regclass</primary>
26414 </indexterm>
26415 <function>to_regclass</function> ( <type>text</type> )
26416 <returnvalue>regclass</returnvalue>
26417 </para>
26418 <para>
26419 Translates a textual relation name to its OID. A similar result is
26420 obtained by casting the string to type <type>regclass</type> (see
26421 <xref linkend="datatype-oid"/>); however, this function will return
26422 <literal>NULL</literal> rather than throwing an error if the name is
26423 not found.
26424 </para></entry>
26425 </row>
26427 <row>
26428 <entry role="func_table_entry"><para role="func_signature">
26429 <indexterm>
26430 <primary>to_regcollation</primary>
26431 </indexterm>
26432 <function>to_regcollation</function> ( <type>text</type> )
26433 <returnvalue>regcollation</returnvalue>
26434 </para>
26435 <para>
26436 Translates a textual collation name to its OID. A similar result is
26437 obtained by casting the string to type <type>regcollation</type> (see
26438 <xref linkend="datatype-oid"/>); however, this function will return
26439 <literal>NULL</literal> rather than throwing an error if the name is
26440 not found.
26441 </para></entry>
26442 </row>
26444 <row>
26445 <entry role="func_table_entry"><para role="func_signature">
26446 <indexterm>
26447 <primary>to_regnamespace</primary>
26448 </indexterm>
26449 <function>to_regnamespace</function> ( <type>text</type> )
26450 <returnvalue>regnamespace</returnvalue>
26451 </para>
26452 <para>
26453 Translates a textual schema name to its OID. A similar result is
26454 obtained by casting the string to type <type>regnamespace</type> (see
26455 <xref linkend="datatype-oid"/>); however, this function will return
26456 <literal>NULL</literal> rather than throwing an error if the name is
26457 not found.
26458 </para></entry>
26459 </row>
26461 <row>
26462 <entry role="func_table_entry"><para role="func_signature">
26463 <indexterm>
26464 <primary>to_regoper</primary>
26465 </indexterm>
26466 <function>to_regoper</function> ( <type>text</type> )
26467 <returnvalue>regoper</returnvalue>
26468 </para>
26469 <para>
26470 Translates a textual operator name to its OID. A similar result is
26471 obtained by casting the string to type <type>regoper</type> (see
26472 <xref linkend="datatype-oid"/>); however, this function will return
26473 <literal>NULL</literal> rather than throwing an error if the name is
26474 not found or is ambiguous.
26475 </para></entry>
26476 </row>
26478 <row>
26479 <entry role="func_table_entry"><para role="func_signature">
26480 <indexterm>
26481 <primary>to_regoperator</primary>
26482 </indexterm>
26483 <function>to_regoperator</function> ( <type>text</type> )
26484 <returnvalue>regoperator</returnvalue>
26485 </para>
26486 <para>
26487 Translates a textual operator name (with parameter types) to its OID. A similar result is
26488 obtained by casting the string to type <type>regoperator</type> (see
26489 <xref linkend="datatype-oid"/>); however, this function will return
26490 <literal>NULL</literal> rather than throwing an error if the name is
26491 not found.
26492 </para></entry>
26493 </row>
26495 <row>
26496 <entry role="func_table_entry"><para role="func_signature">
26497 <indexterm>
26498 <primary>to_regproc</primary>
26499 </indexterm>
26500 <function>to_regproc</function> ( <type>text</type> )
26501 <returnvalue>regproc</returnvalue>
26502 </para>
26503 <para>
26504 Translates a textual function or procedure name to its OID. A similar result is
26505 obtained by casting the string to type <type>regproc</type> (see
26506 <xref linkend="datatype-oid"/>); however, this function will return
26507 <literal>NULL</literal> rather than throwing an error if the name is
26508 not found or is ambiguous.
26509 </para></entry>
26510 </row>
26512 <row>
26513 <entry role="func_table_entry"><para role="func_signature">
26514 <indexterm>
26515 <primary>to_regprocedure</primary>
26516 </indexterm>
26517 <function>to_regprocedure</function> ( <type>text</type> )
26518 <returnvalue>regprocedure</returnvalue>
26519 </para>
26520 <para>
26521 Translates a textual function or procedure name (with argument types) to its OID. A similar result is
26522 obtained by casting the string to type <type>regprocedure</type> (see
26523 <xref linkend="datatype-oid"/>); however, this function will return
26524 <literal>NULL</literal> rather than throwing an error if the name is
26525 not found.
26526 </para></entry>
26527 </row>
26529 <row>
26530 <entry role="func_table_entry"><para role="func_signature">
26531 <indexterm>
26532 <primary>to_regrole</primary>
26533 </indexterm>
26534 <function>to_regrole</function> ( <type>text</type> )
26535 <returnvalue>regrole</returnvalue>
26536 </para>
26537 <para>
26538 Translates a textual role name to its OID. A similar result is
26539 obtained by casting the string to type <type>regrole</type> (see
26540 <xref linkend="datatype-oid"/>); however, this function will return
26541 <literal>NULL</literal> rather than throwing an error if the name is
26542 not found.
26543 </para></entry>
26544 </row>
26546 <row>
26547 <entry id="to-regtype" xreflabel="to_regtype" role="func_table_entry"><para role="func_signature">
26548 <indexterm>
26549 <primary>to_regtype</primary>
26550 </indexterm>
26551 <function>to_regtype</function> ( <type>text</type> )
26552 <returnvalue>regtype</returnvalue>
26553 </para>
26554 <para>
26555 Parses a string of text, extracts a potential type name from it,
26556 and translates that name into a type OID. A syntax error in the
26557 string will result in an error; but if the string is a
26558 syntactically valid type name that happens not to be found in the
26559 catalogs, the result is <literal>NULL</literal>. A similar result
26560 is obtained by casting the string to type <type>regtype</type>
26561 (see <xref linkend="datatype-oid"/>), except that that will throw
26562 error for name not found.
26563 </para></entry>
26564 </row>
26566 <row>
26567 <entry role="func_table_entry"><para role="func_signature">
26568 <indexterm>
26569 <primary>to_regtypemod</primary>
26570 </indexterm>
26571 <function>to_regtypemod</function> ( <type>text</type> )
26572 <returnvalue>integer</returnvalue>
26573 </para>
26574 <para>
26575 Parses a string of text, extracts a potential type name from it,
26576 and translates its type modifier, if any. A syntax error in the
26577 string will result in an error; but if the string is a
26578 syntactically valid type name that happens not to be found in the
26579 catalogs, the result is <literal>NULL</literal>. The result is
26580 <literal>-1</literal> if no type modifier is present.
26581 </para>
26582 <para>
26583 <function>to_regtypemod</function> can be combined with
26584 <xref linkend="to-regtype"/> to produce appropriate inputs for
26585 <xref linkend="format-type"/>, allowing a string representing a
26586 type name to be canonicalized.
26587 </para>
26588 <para>
26589 <literal>format_type(to_regtype('varchar(32)'), to_regtypemod('varchar(32)'))</literal>
26590 <returnvalue>character varying(32)</returnvalue>
26591 </para></entry>
26592 </row>
26593 </tbody>
26594 </tgroup>
26595 </table>
26597 <para>
26598 Most of the functions that reconstruct (decompile) database objects
26599 have an optional <parameter>pretty</parameter> flag, which
26600 if <literal>true</literal> causes the result to
26601 be <quote>pretty-printed</quote>. Pretty-printing suppresses unnecessary
26602 parentheses and adds whitespace for legibility.
26603 The pretty-printed format is more readable, but the default format
26604 is more likely to be interpreted the same way by future versions of
26605 <productname>PostgreSQL</productname>; so avoid using pretty-printed output
26606 for dump purposes. Passing <literal>false</literal> for
26607 the <parameter>pretty</parameter> parameter yields the same result as
26608 omitting the parameter.
26609 </para>
26611 <table id="functions-info-index-column-props">
26612 <title>Index Column Properties</title>
26613 <tgroup cols="2">
26614 <thead>
26615 <row><entry>Name</entry><entry>Description</entry></row>
26616 </thead>
26617 <tbody>
26618 <row>
26619 <entry><literal>asc</literal></entry>
26620 <entry>Does the column sort in ascending order on a forward scan?
26621 </entry>
26622 </row>
26623 <row>
26624 <entry><literal>desc</literal></entry>
26625 <entry>Does the column sort in descending order on a forward scan?
26626 </entry>
26627 </row>
26628 <row>
26629 <entry><literal>nulls_first</literal></entry>
26630 <entry>Does the column sort with nulls first on a forward scan?
26631 </entry>
26632 </row>
26633 <row>
26634 <entry><literal>nulls_last</literal></entry>
26635 <entry>Does the column sort with nulls last on a forward scan?
26636 </entry>
26637 </row>
26638 <row>
26639 <entry><literal>orderable</literal></entry>
26640 <entry>Does the column possess any defined sort ordering?
26641 </entry>
26642 </row>
26643 <row>
26644 <entry><literal>distance_orderable</literal></entry>
26645 <entry>Can the column be scanned in order by a <quote>distance</quote>
26646 operator, for example <literal>ORDER BY col &lt;-&gt; constant</literal> ?
26647 </entry>
26648 </row>
26649 <row>
26650 <entry><literal>returnable</literal></entry>
26651 <entry>Can the column value be returned by an index-only scan?
26652 </entry>
26653 </row>
26654 <row>
26655 <entry><literal>search_array</literal></entry>
26656 <entry>Does the column natively support <literal>col = ANY(array)</literal>
26657 searches?
26658 </entry>
26659 </row>
26660 <row>
26661 <entry><literal>search_nulls</literal></entry>
26662 <entry>Does the column support <literal>IS NULL</literal> and
26663 <literal>IS NOT NULL</literal> searches?
26664 </entry>
26665 </row>
26666 </tbody>
26667 </tgroup>
26668 </table>
26670 <table id="functions-info-index-props">
26671 <title>Index Properties</title>
26672 <tgroup cols="2">
26673 <thead>
26674 <row><entry>Name</entry><entry>Description</entry></row>
26675 </thead>
26676 <tbody>
26677 <row>
26678 <entry><literal>clusterable</literal></entry>
26679 <entry>Can the index be used in a <literal>CLUSTER</literal> command?
26680 </entry>
26681 </row>
26682 <row>
26683 <entry><literal>index_scan</literal></entry>
26684 <entry>Does the index support plain (non-bitmap) scans?
26685 </entry>
26686 </row>
26687 <row>
26688 <entry><literal>bitmap_scan</literal></entry>
26689 <entry>Does the index support bitmap scans?
26690 </entry>
26691 </row>
26692 <row>
26693 <entry><literal>backward_scan</literal></entry>
26694 <entry>Can the scan direction be changed in mid-scan (to
26695 support <literal>FETCH BACKWARD</literal> on a cursor without
26696 needing materialization)?
26697 </entry>
26698 </row>
26699 </tbody>
26700 </tgroup>
26701 </table>
26703 <table id="functions-info-indexam-props">
26704 <title>Index Access Method Properties</title>
26705 <tgroup cols="2">
26706 <thead>
26707 <row><entry>Name</entry><entry>Description</entry></row>
26708 </thead>
26709 <tbody>
26710 <row>
26711 <entry><literal>can_order</literal></entry>
26712 <entry>Does the access method support <literal>ASC</literal>,
26713 <literal>DESC</literal> and related keywords in
26714 <literal>CREATE INDEX</literal>?
26715 </entry>
26716 </row>
26717 <row>
26718 <entry><literal>can_unique</literal></entry>
26719 <entry>Does the access method support unique indexes?
26720 </entry>
26721 </row>
26722 <row>
26723 <entry><literal>can_multi_col</literal></entry>
26724 <entry>Does the access method support indexes with multiple columns?
26725 </entry>
26726 </row>
26727 <row>
26728 <entry><literal>can_exclude</literal></entry>
26729 <entry>Does the access method support exclusion constraints?
26730 </entry>
26731 </row>
26732 <row>
26733 <entry><literal>can_include</literal></entry>
26734 <entry>Does the access method support the <literal>INCLUDE</literal>
26735 clause of <literal>CREATE INDEX</literal>?
26736 </entry>
26737 </row>
26738 </tbody>
26739 </tgroup>
26740 </table>
26742 <table id="functions-pg-settings-flags">
26743 <title>GUC Flags</title>
26744 <tgroup cols="2">
26745 <thead>
26746 <row><entry>Flag</entry><entry>Description</entry></row>
26747 </thead>
26748 <tbody>
26749 <row>
26750 <entry><literal>EXPLAIN</literal></entry>
26751 <entry>Parameters with this flag are included in
26752 <command>EXPLAIN (SETTINGS)</command> commands.
26753 </entry>
26754 </row>
26755 <row>
26756 <entry><literal>NO_SHOW_ALL</literal></entry>
26757 <entry>Parameters with this flag are excluded from
26758 <command>SHOW ALL</command> commands.
26759 </entry>
26760 </row>
26761 <row>
26762 <entry><literal>NO_RESET</literal></entry>
26763 <entry>Parameters with this flag do not support
26764 <command>RESET</command> commands.
26765 </entry>
26766 </row>
26767 <row>
26768 <entry><literal>NO_RESET_ALL</literal></entry>
26769 <entry>Parameters with this flag are excluded from
26770 <command>RESET ALL</command> commands.
26771 </entry>
26772 </row>
26773 <row>
26774 <entry><literal>NOT_IN_SAMPLE</literal></entry>
26775 <entry>Parameters with this flag are not included in
26776 <filename>postgresql.conf</filename> by default.
26777 </entry>
26778 </row>
26779 <row>
26780 <entry><literal>RUNTIME_COMPUTED</literal></entry>
26781 <entry>Parameters with this flag are runtime-computed ones.
26782 </entry>
26783 </row>
26784 </tbody>
26785 </tgroup>
26786 </table>
26788 </sect2>
26790 <sect2 id="functions-info-object">
26791 <title>Object Information and Addressing Functions</title>
26793 <para>
26794 <xref linkend="functions-info-object-table"/> lists functions related to
26795 database object identification and addressing.
26796 </para>
26798 <table id="functions-info-object-table">
26799 <title>Object Information and Addressing Functions</title>
26800 <tgroup cols="1">
26801 <thead>
26802 <row>
26803 <entry role="func_table_entry"><para role="func_signature">
26804 Function
26805 </para>
26806 <para>
26807 Description
26808 </para></entry>
26809 </row>
26810 </thead>
26812 <tbody>
26813 <row>
26814 <entry role="func_table_entry"><para role="func_signature">
26815 <indexterm>
26816 <primary>pg_get_acl</primary>
26817 </indexterm>
26818 <function>pg_get_acl</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
26819 <returnvalue>aclitem[]</returnvalue>
26820 </para>
26821 <para>
26822 Returns the <acronym>ACL</acronym> for a database object, specified
26823 by catalog OID, object OID and sub-object ID. This function returns
26824 <literal>NULL</literal> values for undefined objects.
26825 </para></entry>
26826 </row>
26828 <row>
26829 <entry role="func_table_entry"><para role="func_signature">
26830 <indexterm>
26831 <primary>pg_describe_object</primary>
26832 </indexterm>
26833 <function>pg_describe_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
26834 <returnvalue>text</returnvalue>
26835 </para>
26836 <para>
26837 Returns a textual description of a database object identified by
26838 catalog OID, object OID, and sub-object ID (such as a column number
26839 within a table; the sub-object ID is zero when referring to a whole
26840 object). This description is intended to be human-readable, and might
26841 be translated, depending on server configuration. This is especially
26842 useful to determine the identity of an object referenced in the
26843 <structname>pg_depend</structname> catalog. This function returns
26844 <literal>NULL</literal> values for undefined objects.
26845 </para></entry>
26846 </row>
26848 <row>
26849 <entry role="func_table_entry"><para role="func_signature">
26850 <indexterm>
26851 <primary>pg_identify_object</primary>
26852 </indexterm>
26853 <function>pg_identify_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
26854 <returnvalue>record</returnvalue>
26855 ( <parameter>type</parameter> <type>text</type>,
26856 <parameter>schema</parameter> <type>text</type>,
26857 <parameter>name</parameter> <type>text</type>,
26858 <parameter>identity</parameter> <type>text</type> )
26859 </para>
26860 <para>
26861 Returns a row containing enough information to uniquely identify the
26862 database object specified by catalog OID, object OID and sub-object
26864 This information is intended to be machine-readable, and is never
26865 translated.
26866 <parameter>type</parameter> identifies the type of database object;
26867 <parameter>schema</parameter> is the schema name that the object
26868 belongs in, or <literal>NULL</literal> for object types that do not
26869 belong to schemas;
26870 <parameter>name</parameter> is the name of the object, quoted if
26871 necessary, if the name (along with schema name, if pertinent) is
26872 sufficient to uniquely identify the object,
26873 otherwise <literal>NULL</literal>;
26874 <parameter>identity</parameter> is the complete object identity, with
26875 the precise format depending on object type, and each name within the
26876 format being schema-qualified and quoted as necessary. Undefined
26877 objects are identified with <literal>NULL</literal> values.
26878 </para></entry>
26879 </row>
26881 <row>
26882 <entry role="func_table_entry"><para role="func_signature">
26883 <indexterm>
26884 <primary>pg_identify_object_as_address</primary>
26885 </indexterm>
26886 <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> )
26887 <returnvalue>record</returnvalue>
26888 ( <parameter>type</parameter> <type>text</type>,
26889 <parameter>object_names</parameter> <type>text[]</type>,
26890 <parameter>object_args</parameter> <type>text[]</type> )
26891 </para>
26892 <para>
26893 Returns a row containing enough information to uniquely identify the
26894 database object specified by catalog OID, object OID and sub-object
26896 The returned information is independent of the current server, that
26897 is, it could be used to identify an identically named object in
26898 another server.
26899 <parameter>type</parameter> identifies the type of database object;
26900 <parameter>object_names</parameter> and
26901 <parameter>object_args</parameter>
26902 are text arrays that together form a reference to the object.
26903 These three values can be passed
26904 to <function>pg_get_object_address</function> to obtain the internal
26905 address of the object.
26906 </para></entry>
26907 </row>
26909 <row>
26910 <entry role="func_table_entry"><para role="func_signature">
26911 <indexterm>
26912 <primary>pg_get_object_address</primary>
26913 </indexterm>
26914 <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> )
26915 <returnvalue>record</returnvalue>
26916 ( <parameter>classid</parameter> <type>oid</type>,
26917 <parameter>objid</parameter> <type>oid</type>,
26918 <parameter>objsubid</parameter> <type>integer</type> )
26919 </para>
26920 <para>
26921 Returns a row containing enough information to uniquely identify the
26922 database object specified by a type code and object name and argument
26923 arrays.
26924 The returned values are the ones that would be used in system catalogs
26925 such as <structname>pg_depend</structname>; they can be passed to
26926 other system functions such as <function>pg_describe_object</function>
26927 or <function>pg_identify_object</function>.
26928 <parameter>classid</parameter> is the OID of the system catalog
26929 containing the object;
26930 <parameter>objid</parameter> is the OID of the object itself, and
26931 <parameter>objsubid</parameter> is the sub-object ID, or zero if none.
26932 This function is the inverse
26933 of <function>pg_identify_object_as_address</function>.
26934 Undefined objects are identified with <literal>NULL</literal> values.
26935 </para></entry>
26936 </row>
26937 </tbody>
26938 </tgroup>
26939 </table>
26941 <para>
26942 <function>pg_get_acl</function> is useful for retrieving and inspecting
26943 the privileges associated with database objects without looking at
26944 specific catalogs. For example, to retrieve all the granted privileges
26945 on objects in the current database:
26946 <programlisting>
26947 postgres=# SELECT
26948 (pg_identify_object(s.classid,s.objid,s.objsubid)).*,
26949 pg_catalog.pg_get_acl(s.classid,s.objid,s.objsubid) AS acl
26950 FROM pg_catalog.pg_shdepend AS s
26951 JOIN pg_catalog.pg_database AS d
26952 ON d.datname = current_database() AND
26953 d.oid = s.dbid
26954 JOIN pg_catalog.pg_authid AS a
26955 ON a.oid = s.refobjid AND
26956 s.refclassid = 'pg_authid'::regclass
26957 WHERE s.deptype = 'a';
26958 -[ RECORD 1 ]-----------------------------------------
26959 type | table
26960 schema | public
26961 name | testtab
26962 identity | public.testtab
26963 acl | {postgres=arwdDxtm/postgres,foo=r/postgres}
26964 </programlisting>
26965 </para>
26967 </sect2>
26969 <sect2 id="functions-info-comment">
26970 <title>Comment Information Functions</title>
26972 <indexterm>
26973 <primary>comment</primary>
26974 <secondary sortas="database objects">about database objects</secondary>
26975 </indexterm>
26977 <para>
26978 The functions shown in <xref linkend="functions-info-comment-table"/>
26979 extract comments previously stored with the <xref linkend="sql-comment"/>
26980 command. A null value is returned if no
26981 comment could be found for the specified parameters.
26982 </para>
26984 <table id="functions-info-comment-table">
26985 <title>Comment Information Functions</title>
26986 <tgroup cols="1">
26987 <thead>
26988 <row>
26989 <entry role="func_table_entry"><para role="func_signature">
26990 Function
26991 </para>
26992 <para>
26993 Description
26994 </para></entry>
26995 </row>
26996 </thead>
26998 <tbody>
26999 <row>
27000 <entry role="func_table_entry"><para role="func_signature">
27001 <indexterm>
27002 <primary>col_description</primary>
27003 </indexterm>
27004 <function>col_description</function> ( <parameter>table</parameter> <type>oid</type>, <parameter>column</parameter> <type>integer</type> )
27005 <returnvalue>text</returnvalue>
27006 </para>
27007 <para>
27008 Returns the comment for a table column, which is specified by the OID
27009 of its table and its column number.
27010 (<function>obj_description</function> cannot be used for table
27011 columns, since columns do not have OIDs of their own.)
27012 </para></entry>
27013 </row>
27015 <row>
27016 <entry role="func_table_entry"><para role="func_signature">
27017 <indexterm>
27018 <primary>obj_description</primary>
27019 </indexterm>
27020 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
27021 <returnvalue>text</returnvalue>
27022 </para>
27023 <para>
27024 Returns the comment for a database object specified by its OID and the
27025 name of the containing system catalog. For
27026 example, <literal>obj_description(123456, 'pg_class')</literal> would
27027 retrieve the comment for the table with OID 123456.
27028 </para></entry>
27029 </row>
27031 <row>
27032 <entry role="func_table_entry"><para role="func_signature">
27033 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type> )
27034 <returnvalue>text</returnvalue>
27035 </para>
27036 <para>
27037 Returns the comment for a database object specified by its OID alone.
27038 This is <emphasis>deprecated</emphasis> since there is no guarantee
27039 that OIDs are unique across different system catalogs; therefore, the
27040 wrong comment might be returned.
27041 </para></entry>
27042 </row>
27044 <row>
27045 <entry role="func_table_entry"><para role="func_signature">
27046 <indexterm>
27047 <primary>shobj_description</primary>
27048 </indexterm>
27049 <function>shobj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
27050 <returnvalue>text</returnvalue>
27051 </para>
27052 <para>
27053 Returns the comment for a shared database object specified by its OID
27054 and the name of the containing system catalog. This is just
27055 like <function>obj_description</function> except that it is used for
27056 retrieving comments on shared objects (that is, databases, roles, and
27057 tablespaces). Some system catalogs are global to all databases within
27058 each cluster, and the descriptions for objects in them are stored
27059 globally as well.
27060 </para></entry>
27061 </row>
27062 </tbody>
27063 </tgroup>
27064 </table>
27066 </sect2>
27068 <sect2 id="functions-info-validity">
27069 <title>Data Validity Checking Functions</title>
27071 <para>
27072 The functions shown in <xref linkend="functions-info-validity-table"/>
27073 can be helpful for checking validity of proposed input data.
27074 </para>
27076 <table id="functions-info-validity-table">
27077 <title>Data Validity Checking Functions</title>
27078 <tgroup cols="1">
27079 <thead>
27080 <row>
27081 <entry role="func_table_entry"><para role="func_signature">
27082 Function
27083 </para>
27084 <para>
27085 Description
27086 </para>
27087 <para>
27088 Example(s)
27089 </para></entry>
27090 </row>
27091 </thead>
27093 <tbody>
27094 <row>
27095 <entry role="func_table_entry"><para role="func_signature">
27096 <indexterm>
27097 <primary>pg_input_is_valid</primary>
27098 </indexterm>
27099 <function>pg_input_is_valid</function> (
27100 <parameter>string</parameter> <type>text</type>,
27101 <parameter>type</parameter> <type>text</type>
27103 <returnvalue>boolean</returnvalue>
27104 </para>
27105 <para>
27106 Tests whether the given <parameter>string</parameter> is valid
27107 input for the specified data type, returning true or false.
27108 </para>
27109 <para>
27110 This function will only work as desired if the data type's input
27111 function has been updated to report invalid input as
27112 a <quote>soft</quote> error. Otherwise, invalid input will abort
27113 the transaction, just as if the string had been cast to the type
27114 directly.
27115 </para>
27116 <para>
27117 <literal>pg_input_is_valid('42', 'integer')</literal>
27118 <returnvalue>t</returnvalue>
27119 </para>
27120 <para>
27121 <literal>pg_input_is_valid('42000000000', 'integer')</literal>
27122 <returnvalue>f</returnvalue>
27123 </para>
27124 <para>
27125 <literal>pg_input_is_valid('1234.567', 'numeric(7,4)')</literal>
27126 <returnvalue>f</returnvalue>
27127 </para></entry>
27128 </row>
27129 <row>
27130 <entry role="func_table_entry"><para role="func_signature">
27131 <indexterm>
27132 <primary>pg_input_error_info</primary>
27133 </indexterm>
27134 <function>pg_input_error_info</function> (
27135 <parameter>string</parameter> <type>text</type>,
27136 <parameter>type</parameter> <type>text</type>
27138 <returnvalue>record</returnvalue>
27139 ( <parameter>message</parameter> <type>text</type>,
27140 <parameter>detail</parameter> <type>text</type>,
27141 <parameter>hint</parameter> <type>text</type>,
27142 <parameter>sql_error_code</parameter> <type>text</type> )
27143 </para>
27144 <para>
27145 Tests whether the given <parameter>string</parameter> is valid
27146 input for the specified data type; if not, return the details of
27147 the error that would have been thrown. If the input is valid, the
27148 results are NULL. The inputs are the same as
27149 for <function>pg_input_is_valid</function>.
27150 </para>
27151 <para>
27152 This function will only work as desired if the data type's input
27153 function has been updated to report invalid input as
27154 a <quote>soft</quote> error. Otherwise, invalid input will abort
27155 the transaction, just as if the string had been cast to the type
27156 directly.
27157 </para>
27158 <para>
27159 <literal>SELECT * FROM pg_input_error_info('42000000000', 'integer')</literal>
27160 <returnvalue></returnvalue>
27161 <programlisting>
27162 message | detail | hint | sql_error_code
27163 ------------------------------------------------------+--------+------+----------------
27164 value "42000000000" is out of range for type integer | | | 22003
27165 </programlisting>
27166 </para></entry>
27167 </row>
27168 </tbody>
27169 </tgroup>
27170 </table>
27172 </sect2>
27174 <sect2 id="functions-info-snapshot">
27175 <title>Transaction ID and Snapshot Information Functions</title>
27177 <para>
27178 The functions shown in <xref linkend="functions-pg-snapshot"/>
27179 provide server transaction information in an exportable form. The main
27180 use of these functions is to determine which transactions were committed
27181 between two snapshots.
27182 </para>
27184 <table id="functions-pg-snapshot">
27185 <title>Transaction ID and Snapshot Information Functions</title>
27186 <tgroup cols="1">
27187 <thead>
27188 <row>
27189 <entry role="func_table_entry"><para role="func_signature">
27190 Function
27191 </para>
27192 <para>
27193 Description
27194 </para></entry>
27195 </row>
27196 </thead>
27198 <tbody>
27199 <row>
27200 <entry role="func_table_entry"><para role="func_signature">
27201 <indexterm>
27202 <primary>age</primary>
27203 </indexterm>
27204 <function>age</function> ( <type>xid</type> )
27205 <returnvalue>integer</returnvalue>
27206 </para>
27207 <para>
27208 Returns the number of transactions between the supplied
27209 transaction id and the current transaction counter.
27210 </para></entry>
27211 </row>
27213 <row>
27214 <entry role="func_table_entry"><para role="func_signature">
27215 <indexterm>
27216 <primary>mxid_age</primary>
27217 </indexterm>
27218 <function>mxid_age</function> ( <type>xid</type> )
27219 <returnvalue>integer</returnvalue>
27220 </para>
27221 <para>
27222 Returns the number of multixacts IDs between the supplied
27223 multixact ID and the current multixacts counter.
27224 </para></entry>
27225 </row>
27227 <row>
27228 <entry role="func_table_entry"><para role="func_signature">
27229 <indexterm>
27230 <primary>pg_current_xact_id</primary>
27231 </indexterm>
27232 <function>pg_current_xact_id</function> ()
27233 <returnvalue>xid8</returnvalue>
27234 </para>
27235 <para>
27236 Returns the current transaction's ID. It will assign a new one if the
27237 current transaction does not have one already (because it has not
27238 performed any database updates); see <xref
27239 linkend="transaction-id"/> for details. If executed in a
27240 subtransaction, this will return the top-level transaction ID;
27241 see <xref linkend="subxacts"/> for details.
27242 </para></entry>
27243 </row>
27245 <row>
27246 <entry role="func_table_entry"><para role="func_signature">
27247 <indexterm>
27248 <primary>pg_current_xact_id_if_assigned</primary>
27249 </indexterm>
27250 <function>pg_current_xact_id_if_assigned</function> ()
27251 <returnvalue>xid8</returnvalue>
27252 </para>
27253 <para>
27254 Returns the current transaction's ID, or <literal>NULL</literal> if no
27255 ID is assigned yet. (It's best to use this variant if the transaction
27256 might otherwise be read-only, to avoid unnecessary consumption of an
27257 XID.)
27258 If executed in a subtransaction, this will return the top-level
27259 transaction ID.
27260 </para></entry>
27261 </row>
27263 <row>
27264 <entry role="func_table_entry"><para role="func_signature">
27265 <indexterm>
27266 <primary>pg_xact_status</primary>
27267 </indexterm>
27268 <function>pg_xact_status</function> ( <type>xid8</type> )
27269 <returnvalue>text</returnvalue>
27270 </para>
27271 <para>
27272 Reports the commit status of a recent transaction.
27273 The result is one of <literal>in progress</literal>,
27274 <literal>committed</literal>, or <literal>aborted</literal>,
27275 provided that the transaction is recent enough that the system retains
27276 the commit status of that transaction.
27277 If it is old enough that no references to the transaction survive in
27278 the system and the commit status information has been discarded, the
27279 result is <literal>NULL</literal>.
27280 Applications might use this function, for example, to determine
27281 whether their transaction committed or aborted after the application
27282 and database server become disconnected while
27283 a <literal>COMMIT</literal> is in progress.
27284 Note that prepared transactions are reported as <literal>in
27285 progress</literal>; applications must check <link
27286 linkend="view-pg-prepared-xacts"><structname>pg_prepared_xacts</structname></link>
27287 if they need to determine whether a transaction ID belongs to a
27288 prepared transaction.
27289 </para></entry>
27290 </row>
27292 <row>
27293 <entry role="func_table_entry"><para role="func_signature">
27294 <indexterm>
27295 <primary>pg_current_snapshot</primary>
27296 </indexterm>
27297 <function>pg_current_snapshot</function> ()
27298 <returnvalue>pg_snapshot</returnvalue>
27299 </para>
27300 <para>
27301 Returns a current <firstterm>snapshot</firstterm>, a data structure
27302 showing which transaction IDs are now in-progress.
27303 Only top-level transaction IDs are included in the snapshot;
27304 subtransaction IDs are not shown; see <xref linkend="subxacts"/>
27305 for details.
27306 </para></entry>
27307 </row>
27309 <row>
27310 <entry role="func_table_entry"><para role="func_signature">
27311 <indexterm>
27312 <primary>pg_snapshot_xip</primary>
27313 </indexterm>
27314 <function>pg_snapshot_xip</function> ( <type>pg_snapshot</type> )
27315 <returnvalue>setof xid8</returnvalue>
27316 </para>
27317 <para>
27318 Returns the set of in-progress transaction IDs contained in a snapshot.
27319 </para></entry>
27320 </row>
27322 <row>
27323 <entry role="func_table_entry"><para role="func_signature">
27324 <indexterm>
27325 <primary>pg_snapshot_xmax</primary>
27326 </indexterm>
27327 <function>pg_snapshot_xmax</function> ( <type>pg_snapshot</type> )
27328 <returnvalue>xid8</returnvalue>
27329 </para>
27330 <para>
27331 Returns the <structfield>xmax</structfield> of a snapshot.
27332 </para></entry>
27333 </row>
27335 <row>
27336 <entry role="func_table_entry"><para role="func_signature">
27337 <indexterm>
27338 <primary>pg_snapshot_xmin</primary>
27339 </indexterm>
27340 <function>pg_snapshot_xmin</function> ( <type>pg_snapshot</type> )
27341 <returnvalue>xid8</returnvalue>
27342 </para>
27343 <para>
27344 Returns the <structfield>xmin</structfield> of a snapshot.
27345 </para></entry>
27346 </row>
27348 <row>
27349 <entry role="func_table_entry"><para role="func_signature">
27350 <indexterm>
27351 <primary>pg_visible_in_snapshot</primary>
27352 </indexterm>
27353 <function>pg_visible_in_snapshot</function> ( <type>xid8</type>, <type>pg_snapshot</type> )
27354 <returnvalue>boolean</returnvalue>
27355 </para>
27356 <para>
27357 Is the given transaction ID <firstterm>visible</firstterm> according
27358 to this snapshot (that is, was it completed before the snapshot was
27359 taken)? Note that this function will not give the correct answer for
27360 a subtransaction ID (subxid); see <xref linkend="subxacts"/> for
27361 details.
27362 </para></entry>
27363 </row>
27364 </tbody>
27365 </tgroup>
27366 </table>
27368 <para>
27369 The internal transaction ID type <type>xid</type> is 32 bits wide and
27370 wraps around every 4 billion transactions. However,
27371 the functions shown in <xref linkend="functions-pg-snapshot"/>, except
27372 <function>age</function> and <function>mxid_age</function>, use a
27373 64-bit type <type>xid8</type> that does not wrap around during the life
27374 of an installation and can be converted to <type>xid</type> by casting if
27375 required; see <xref linkend="transaction-id"/> for details.
27376 The data type <type>pg_snapshot</type> stores information about
27377 transaction ID visibility at a particular moment in time. Its components
27378 are described in <xref linkend="functions-pg-snapshot-parts"/>.
27379 <type>pg_snapshot</type>'s textual representation is
27380 <literal><replaceable>xmin</replaceable>:<replaceable>xmax</replaceable>:<replaceable>xip_list</replaceable></literal>.
27381 For example <literal>10:20:10,14,15</literal> means
27382 <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
27383 </para>
27385 <table id="functions-pg-snapshot-parts">
27386 <title>Snapshot Components</title>
27387 <tgroup cols="2">
27388 <thead>
27389 <row>
27390 <entry>Name</entry>
27391 <entry>Description</entry>
27392 </row>
27393 </thead>
27395 <tbody>
27396 <row>
27397 <entry><structfield>xmin</structfield></entry>
27398 <entry>
27399 Lowest transaction ID that was still active. All transaction IDs
27400 less than <structfield>xmin</structfield> are either committed and visible,
27401 or rolled back and dead.
27402 </entry>
27403 </row>
27405 <row>
27406 <entry><structfield>xmax</structfield></entry>
27407 <entry>
27408 One past the highest completed transaction ID. All transaction IDs
27409 greater than or equal to <structfield>xmax</structfield> had not yet
27410 completed as of the time of the snapshot, and thus are invisible.
27411 </entry>
27412 </row>
27414 <row>
27415 <entry><structfield>xip_list</structfield></entry>
27416 <entry>
27417 Transactions in progress at the time of the snapshot. A transaction
27418 ID that is <literal>xmin &lt;= <replaceable>X</replaceable> &lt;
27419 xmax</literal> and not in this list was already completed at the time
27420 of the snapshot, and thus is either visible or dead according to its
27421 commit status. This list does not include the transaction IDs of
27422 subtransactions (subxids).
27423 </entry>
27424 </row>
27425 </tbody>
27426 </tgroup>
27427 </table>
27429 <para>
27430 In releases of <productname>PostgreSQL</productname> before 13 there was
27431 no <type>xid8</type> type, so variants of these functions were provided
27432 that used <type>bigint</type> to represent a 64-bit XID, with a
27433 correspondingly distinct snapshot data type <type>txid_snapshot</type>.
27434 These older functions have <literal>txid</literal> in their names. They
27435 are still supported for backward compatibility, but may be removed from a
27436 future release. See <xref linkend="functions-txid-snapshot"/>.
27437 </para>
27439 <table id="functions-txid-snapshot">
27440 <title>Deprecated Transaction ID and Snapshot Information Functions</title>
27441 <tgroup cols="1">
27442 <thead>
27443 <row>
27444 <entry role="func_table_entry"><para role="func_signature">
27445 Function
27446 </para>
27447 <para>
27448 Description
27449 </para></entry>
27450 </row>
27451 </thead>
27453 <tbody>
27455 <row>
27456 <entry role="func_table_entry"><para role="func_signature">
27457 <indexterm>
27458 <primary>txid_current</primary>
27459 </indexterm>
27460 <function>txid_current</function> ()
27461 <returnvalue>bigint</returnvalue>
27462 </para>
27463 <para>
27464 See <function>pg_current_xact_id()</function>.
27465 </para></entry>
27466 </row>
27468 <row>
27469 <entry role="func_table_entry"><para role="func_signature">
27470 <indexterm>
27471 <primary>txid_current_if_assigned</primary>
27472 </indexterm>
27473 <function>txid_current_if_assigned</function> ()
27474 <returnvalue>bigint</returnvalue>
27475 </para>
27476 <para>
27477 See <function>pg_current_xact_id_if_assigned()</function>.
27478 </para></entry>
27479 </row>
27481 <row>
27482 <entry role="func_table_entry"><para role="func_signature">
27483 <indexterm>
27484 <primary>txid_current_snapshot</primary>
27485 </indexterm>
27486 <function>txid_current_snapshot</function> ()
27487 <returnvalue>txid_snapshot</returnvalue>
27488 </para>
27489 <para>
27490 See <function>pg_current_snapshot()</function>.
27491 </para></entry>
27492 </row>
27494 <row>
27495 <entry role="func_table_entry"><para role="func_signature">
27496 <indexterm>
27497 <primary>txid_snapshot_xip</primary>
27498 </indexterm>
27499 <function>txid_snapshot_xip</function> ( <type>txid_snapshot</type> )
27500 <returnvalue>setof bigint</returnvalue>
27501 </para>
27502 <para>
27503 See <function>pg_snapshot_xip()</function>.
27504 </para></entry>
27505 </row>
27507 <row>
27508 <entry role="func_table_entry"><para role="func_signature">
27509 <indexterm>
27510 <primary>txid_snapshot_xmax</primary>
27511 </indexterm>
27512 <function>txid_snapshot_xmax</function> ( <type>txid_snapshot</type> )
27513 <returnvalue>bigint</returnvalue>
27514 </para>
27515 <para>
27516 See <function>pg_snapshot_xmax()</function>.
27517 </para></entry>
27518 </row>
27520 <row>
27521 <entry role="func_table_entry"><para role="func_signature">
27522 <indexterm>
27523 <primary>txid_snapshot_xmin</primary>
27524 </indexterm>
27525 <function>txid_snapshot_xmin</function> ( <type>txid_snapshot</type> )
27526 <returnvalue>bigint</returnvalue>
27527 </para>
27528 <para>
27529 See <function>pg_snapshot_xmin()</function>.
27530 </para></entry>
27531 </row>
27533 <row>
27534 <entry role="func_table_entry"><para role="func_signature">
27535 <indexterm>
27536 <primary>txid_visible_in_snapshot</primary>
27537 </indexterm>
27538 <function>txid_visible_in_snapshot</function> ( <type>bigint</type>, <type>txid_snapshot</type> )
27539 <returnvalue>boolean</returnvalue>
27540 </para>
27541 <para>
27542 See <function>pg_visible_in_snapshot()</function>.
27543 </para></entry>
27544 </row>
27546 <row>
27547 <entry role="func_table_entry"><para role="func_signature">
27548 <indexterm>
27549 <primary>txid_status</primary>
27550 </indexterm>
27551 <function>txid_status</function> ( <type>bigint</type> )
27552 <returnvalue>text</returnvalue>
27553 </para>
27554 <para>
27555 See <function>pg_xact_status()</function>.
27556 </para></entry>
27557 </row>
27558 </tbody>
27559 </tgroup>
27560 </table>
27562 </sect2>
27564 <sect2 id="functions-info-commit-timestamp">
27565 <title>Committed Transaction Information Functions</title>
27567 <para>
27568 The functions shown in <xref linkend="functions-commit-timestamp"/>
27569 provide information about when past transactions were committed.
27570 They only provide useful data when the
27571 <xref linkend="guc-track-commit-timestamp"/> configuration option is
27572 enabled, and only for transactions that were committed after it was
27573 enabled. Commit timestamp information is routinely removed during
27574 vacuum.
27575 </para>
27577 <table id="functions-commit-timestamp">
27578 <title>Committed Transaction Information Functions</title>
27579 <tgroup cols="1">
27580 <thead>
27581 <row>
27582 <entry role="func_table_entry"><para role="func_signature">
27583 Function
27584 </para>
27585 <para>
27586 Description
27587 </para></entry>
27588 </row>
27589 </thead>
27591 <tbody>
27592 <row>
27593 <entry role="func_table_entry"><para role="func_signature">
27594 <indexterm>
27595 <primary>pg_xact_commit_timestamp</primary>
27596 </indexterm>
27597 <function>pg_xact_commit_timestamp</function> ( <type>xid</type> )
27598 <returnvalue>timestamp with time zone</returnvalue>
27599 </para>
27600 <para>
27601 Returns the commit timestamp of a transaction.
27602 </para></entry>
27603 </row>
27605 <row>
27606 <entry role="func_table_entry"><para role="func_signature">
27607 <indexterm>
27608 <primary>pg_xact_commit_timestamp_origin</primary>
27609 </indexterm>
27610 <function>pg_xact_commit_timestamp_origin</function> ( <type>xid</type> )
27611 <returnvalue>record</returnvalue>
27612 ( <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
27613 <parameter>roident</parameter> <type>oid</type>)
27614 </para>
27615 <para>
27616 Returns the commit timestamp and replication origin of a transaction.
27617 </para></entry>
27618 </row>
27620 <row>
27621 <entry role="func_table_entry"><para role="func_signature">
27622 <indexterm>
27623 <primary>pg_last_committed_xact</primary>
27624 </indexterm>
27625 <function>pg_last_committed_xact</function> ()
27626 <returnvalue>record</returnvalue>
27627 ( <parameter>xid</parameter> <type>xid</type>,
27628 <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
27629 <parameter>roident</parameter> <type>oid</type> )
27630 </para>
27631 <para>
27632 Returns the transaction ID, commit timestamp and replication origin
27633 of the latest committed transaction.
27634 </para></entry>
27635 </row>
27636 </tbody>
27637 </tgroup>
27638 </table>
27640 </sect2>
27642 <sect2 id="functions-info-controldata">
27643 <title>Control Data Functions</title>
27645 <para>
27646 The functions shown in <xref linkend="functions-controldata"/>
27647 print information initialized during <command>initdb</command>, such
27648 as the catalog version. They also show information about write-ahead
27649 logging and checkpoint processing. This information is cluster-wide,
27650 not specific to any one database. These functions provide most of the same
27651 information, from the same source, as the
27652 <xref linkend="app-pgcontroldata"/> application.
27653 </para>
27655 <table id="functions-controldata">
27656 <title>Control Data Functions</title>
27657 <tgroup cols="1">
27658 <thead>
27659 <row>
27660 <entry role="func_table_entry"><para role="func_signature">
27661 Function
27662 </para>
27663 <para>
27664 Description
27665 </para></entry>
27666 </row>
27667 </thead>
27669 <tbody>
27670 <row>
27671 <entry role="func_table_entry"><para role="func_signature">
27672 <indexterm>
27673 <primary>pg_control_checkpoint</primary>
27674 </indexterm>
27675 <function>pg_control_checkpoint</function> ()
27676 <returnvalue>record</returnvalue>
27677 </para>
27678 <para>
27679 Returns information about current checkpoint state, as shown in
27680 <xref linkend="functions-pg-control-checkpoint"/>.
27681 </para></entry>
27682 </row>
27684 <row>
27685 <entry role="func_table_entry"><para role="func_signature">
27686 <indexterm>
27687 <primary>pg_control_system</primary>
27688 </indexterm>
27689 <function>pg_control_system</function> ()
27690 <returnvalue>record</returnvalue>
27691 </para>
27692 <para>
27693 Returns information about current control file state, as shown in
27694 <xref linkend="functions-pg-control-system"/>.
27695 </para></entry>
27696 </row>
27698 <row>
27699 <entry role="func_table_entry"><para role="func_signature">
27700 <indexterm>
27701 <primary>pg_control_init</primary>
27702 </indexterm>
27703 <function>pg_control_init</function> ()
27704 <returnvalue>record</returnvalue>
27705 </para>
27706 <para>
27707 Returns information about cluster initialization state, as shown in
27708 <xref linkend="functions-pg-control-init"/>.
27709 </para></entry>
27710 </row>
27712 <row>
27713 <entry role="func_table_entry"><para role="func_signature">
27714 <indexterm>
27715 <primary>pg_control_recovery</primary>
27716 </indexterm>
27717 <function>pg_control_recovery</function> ()
27718 <returnvalue>record</returnvalue>
27719 </para>
27720 <para>
27721 Returns information about recovery state, as shown in
27722 <xref linkend="functions-pg-control-recovery"/>.
27723 </para></entry>
27724 </row>
27725 </tbody>
27726 </tgroup>
27727 </table>
27729 <table id="functions-pg-control-checkpoint">
27730 <title><function>pg_control_checkpoint</function> Output Columns</title>
27731 <tgroup cols="2">
27732 <thead>
27733 <row>
27734 <entry>Column Name</entry>
27735 <entry>Data Type</entry>
27736 </row>
27737 </thead>
27739 <tbody>
27741 <row>
27742 <entry><structfield>checkpoint_lsn</structfield></entry>
27743 <entry><type>pg_lsn</type></entry>
27744 </row>
27746 <row>
27747 <entry><structfield>redo_lsn</structfield></entry>
27748 <entry><type>pg_lsn</type></entry>
27749 </row>
27751 <row>
27752 <entry><structfield>redo_wal_file</structfield></entry>
27753 <entry><type>text</type></entry>
27754 </row>
27756 <row>
27757 <entry><structfield>timeline_id</structfield></entry>
27758 <entry><type>integer</type></entry>
27759 </row>
27761 <row>
27762 <entry><structfield>prev_timeline_id</structfield></entry>
27763 <entry><type>integer</type></entry>
27764 </row>
27766 <row>
27767 <entry><structfield>full_page_writes</structfield></entry>
27768 <entry><type>boolean</type></entry>
27769 </row>
27771 <row>
27772 <entry><structfield>next_xid</structfield></entry>
27773 <entry><type>text</type></entry>
27774 </row>
27776 <row>
27777 <entry><structfield>next_oid</structfield></entry>
27778 <entry><type>oid</type></entry>
27779 </row>
27781 <row>
27782 <entry><structfield>next_multixact_id</structfield></entry>
27783 <entry><type>xid</type></entry>
27784 </row>
27786 <row>
27787 <entry><structfield>next_multi_offset</structfield></entry>
27788 <entry><type>xid</type></entry>
27789 </row>
27791 <row>
27792 <entry><structfield>oldest_xid</structfield></entry>
27793 <entry><type>xid</type></entry>
27794 </row>
27796 <row>
27797 <entry><structfield>oldest_xid_dbid</structfield></entry>
27798 <entry><type>oid</type></entry>
27799 </row>
27801 <row>
27802 <entry><structfield>oldest_active_xid</structfield></entry>
27803 <entry><type>xid</type></entry>
27804 </row>
27806 <row>
27807 <entry><structfield>oldest_multi_xid</structfield></entry>
27808 <entry><type>xid</type></entry>
27809 </row>
27811 <row>
27812 <entry><structfield>oldest_multi_dbid</structfield></entry>
27813 <entry><type>oid</type></entry>
27814 </row>
27816 <row>
27817 <entry><structfield>oldest_commit_ts_xid</structfield></entry>
27818 <entry><type>xid</type></entry>
27819 </row>
27821 <row>
27822 <entry><structfield>newest_commit_ts_xid</structfield></entry>
27823 <entry><type>xid</type></entry>
27824 </row>
27826 <row>
27827 <entry><structfield>checkpoint_time</structfield></entry>
27828 <entry><type>timestamp with time zone</type></entry>
27829 </row>
27831 </tbody>
27832 </tgroup>
27833 </table>
27835 <table id="functions-pg-control-system">
27836 <title><function>pg_control_system</function> Output Columns</title>
27837 <tgroup cols="2">
27838 <thead>
27839 <row>
27840 <entry>Column Name</entry>
27841 <entry>Data Type</entry>
27842 </row>
27843 </thead>
27845 <tbody>
27847 <row>
27848 <entry><structfield>pg_control_version</structfield></entry>
27849 <entry><type>integer</type></entry>
27850 </row>
27852 <row>
27853 <entry><structfield>catalog_version_no</structfield></entry>
27854 <entry><type>integer</type></entry>
27855 </row>
27857 <row>
27858 <entry><structfield>system_identifier</structfield></entry>
27859 <entry><type>bigint</type></entry>
27860 </row>
27862 <row>
27863 <entry><structfield>pg_control_last_modified</structfield></entry>
27864 <entry><type>timestamp with time zone</type></entry>
27865 </row>
27867 </tbody>
27868 </tgroup>
27869 </table>
27871 <table id="functions-pg-control-init">
27872 <title><function>pg_control_init</function> Output Columns</title>
27873 <tgroup cols="2">
27874 <thead>
27875 <row>
27876 <entry>Column Name</entry>
27877 <entry>Data Type</entry>
27878 </row>
27879 </thead>
27881 <tbody>
27883 <row>
27884 <entry><structfield>max_data_alignment</structfield></entry>
27885 <entry><type>integer</type></entry>
27886 </row>
27888 <row>
27889 <entry><structfield>database_block_size</structfield></entry>
27890 <entry><type>integer</type></entry>
27891 </row>
27893 <row>
27894 <entry><structfield>blocks_per_segment</structfield></entry>
27895 <entry><type>integer</type></entry>
27896 </row>
27898 <row>
27899 <entry><structfield>wal_block_size</structfield></entry>
27900 <entry><type>integer</type></entry>
27901 </row>
27903 <row>
27904 <entry><structfield>bytes_per_wal_segment</structfield></entry>
27905 <entry><type>integer</type></entry>
27906 </row>
27908 <row>
27909 <entry><structfield>max_identifier_length</structfield></entry>
27910 <entry><type>integer</type></entry>
27911 </row>
27913 <row>
27914 <entry><structfield>max_index_columns</structfield></entry>
27915 <entry><type>integer</type></entry>
27916 </row>
27918 <row>
27919 <entry><structfield>max_toast_chunk_size</structfield></entry>
27920 <entry><type>integer</type></entry>
27921 </row>
27923 <row>
27924 <entry><structfield>large_object_chunk_size</structfield></entry>
27925 <entry><type>integer</type></entry>
27926 </row>
27928 <row>
27929 <entry><structfield>float8_pass_by_value</structfield></entry>
27930 <entry><type>boolean</type></entry>
27931 </row>
27933 <row>
27934 <entry><structfield>data_page_checksum_version</structfield></entry>
27935 <entry><type>integer</type></entry>
27936 </row>
27938 </tbody>
27939 </tgroup>
27940 </table>
27942 <table id="functions-pg-control-recovery">
27943 <title><function>pg_control_recovery</function> Output Columns</title>
27944 <tgroup cols="2">
27945 <thead>
27946 <row>
27947 <entry>Column Name</entry>
27948 <entry>Data Type</entry>
27949 </row>
27950 </thead>
27952 <tbody>
27954 <row>
27955 <entry><structfield>min_recovery_end_lsn</structfield></entry>
27956 <entry><type>pg_lsn</type></entry>
27957 </row>
27959 <row>
27960 <entry><structfield>min_recovery_end_timeline</structfield></entry>
27961 <entry><type>integer</type></entry>
27962 </row>
27964 <row>
27965 <entry><structfield>backup_start_lsn</structfield></entry>
27966 <entry><type>pg_lsn</type></entry>
27967 </row>
27969 <row>
27970 <entry><structfield>backup_end_lsn</structfield></entry>
27971 <entry><type>pg_lsn</type></entry>
27972 </row>
27974 <row>
27975 <entry><structfield>end_of_backup_record_required</structfield></entry>
27976 <entry><type>boolean</type></entry>
27977 </row>
27979 </tbody>
27980 </tgroup>
27981 </table>
27983 </sect2>
27985 <sect2 id="functions-info-version">
27986 <title>Version Information Functions</title>
27988 <para>
27989 The functions shown in <xref linkend="functions-version"/>
27990 print version information.
27991 </para>
27993 <table id="functions-version">
27994 <title>Version Information Functions</title>
27995 <tgroup cols="1">
27996 <thead>
27997 <row>
27998 <entry role="func_table_entry"><para role="func_signature">
27999 Function
28000 </para>
28001 <para>
28002 Description
28003 </para></entry>
28004 </row>
28005 </thead>
28007 <tbody>
28008 <row>
28009 <entry role="func_table_entry"><para role="func_signature">
28010 <indexterm>
28011 <primary>version</primary>
28012 </indexterm>
28013 <function>version</function> ()
28014 <returnvalue>text</returnvalue>
28015 </para>
28016 <para>
28017 Returns a string describing the <productname>PostgreSQL</productname>
28018 server's version. You can also get this information from
28019 <xref linkend="guc-server-version"/>, or for a machine-readable
28020 version use <xref linkend="guc-server-version-num"/>. Software
28021 developers should use <varname>server_version_num</varname> (available
28022 since 8.2) or <xref linkend="libpq-PQserverVersion"/> instead of
28023 parsing the text version.
28024 </para></entry>
28025 </row>
28027 <row>
28028 <entry role="func_table_entry"><para role="func_signature">
28029 <indexterm>
28030 <primary>unicode_version</primary>
28031 </indexterm>
28032 <function>unicode_version</function> ()
28033 <returnvalue>text</returnvalue>
28034 </para>
28035 <para>
28036 Returns a string representing the version of Unicode used by
28037 <productname>PostgreSQL</productname>.
28038 </para></entry>
28039 </row>
28040 <row>
28041 <entry role="func_table_entry"><para role="func_signature">
28042 <indexterm>
28043 <primary>icu_unicode_version</primary>
28044 </indexterm>
28045 <function>icu_unicode_version</function> ()
28046 <returnvalue>text</returnvalue>
28047 </para>
28048 <para>
28049 Returns a string representing the version of Unicode used by ICU, if
28050 the server was built with ICU support; otherwise returns
28051 <literal>NULL</literal> </para></entry>
28052 </row>
28053 </tbody>
28054 </tgroup>
28055 </table>
28057 </sect2>
28059 <sect2 id="functions-info-wal-summary">
28060 <title>WAL Summarization Information Functions</title>
28062 <para>
28063 The functions shown in <xref linkend="functions-wal-summary"/>
28064 print information about the status of WAL summarization.
28065 See <xref linkend="guc-summarize-wal" />.
28066 </para>
28068 <table id="functions-wal-summary">
28069 <title>WAL Summarization Information Functions</title>
28070 <tgroup cols="1">
28071 <thead>
28072 <row>
28073 <entry role="func_table_entry"><para role="func_signature">
28074 Function
28075 </para>
28076 <para>
28077 Description
28078 </para></entry>
28079 </row>
28080 </thead>
28082 <tbody>
28083 <row>
28084 <entry role="func_table_entry"><para role="func_signature">
28085 <indexterm>
28086 <primary>pg_available_wal_summaries</primary>
28087 </indexterm>
28088 <function>pg_available_wal_summaries</function> ()
28089 <returnvalue>setof record</returnvalue>
28090 ( <parameter>tli</parameter> <type>bigint</type>,
28091 <parameter>start_lsn</parameter> <type>pg_lsn</type>,
28092 <parameter>end_lsn</parameter> <type>pg_lsn</type> )
28093 </para>
28094 <para>
28095 Returns information about the WAL summary files present in the
28096 data directory, under <literal>pg_wal/summaries</literal>.
28097 One row will be returned per WAL summary file. Each file summarizes
28098 WAL on the indicated TLI within the indicated LSN range. This function
28099 might be useful to determine whether enough WAL summaries are present
28100 on the server to take an incremental backup based on some prior
28101 backup whose start LSN is known.
28102 </para></entry>
28103 </row>
28105 <row>
28106 <entry role="func_table_entry"><para role="func_signature">
28107 <indexterm>
28108 <primary>pg_wal_summary_contents</primary>
28109 </indexterm>
28110 <function>pg_wal_summary_contents</function> ( <parameter>tli</parameter> <type>bigint</type>, <parameter>start_lsn</parameter> <type>pg_lsn</type>, <parameter>end_lsn</parameter> <type>pg_lsn</type> )
28111 <returnvalue>setof record</returnvalue>
28112 ( <parameter>relfilenode</parameter> <type>oid</type>,
28113 <parameter>reltablespace</parameter> <type>oid</type>,
28114 <parameter>reldatabase</parameter> <type>oid</type>,
28115 <parameter>relforknumber</parameter> <type>smallint</type>,
28116 <parameter>relblocknumber</parameter> <type>bigint</type>,
28117 <parameter>is_limit_block</parameter> <type>boolean</type> )
28118 </para>
28119 <para>
28120 Returns one information about the contents of a single WAL summary file
28121 identified by TLI and starting and ending LSNs. Each row with
28122 <literal>is_limit_block</literal> false indicates that the block
28123 identified by the remaining output columns was modified by at least
28124 one WAL record within the range of records summarized by this file.
28125 Each row with <literal>is_limit_block</literal> true indicates either
28126 that (a) the relation fork was truncated to the length given by
28127 <literal>relblocknumber</literal> within the relevant range of WAL
28128 records or (b) that the relation fork was created or dropped within
28129 the relevant range of WAL records; in such cases,
28130 <literal>relblocknumber</literal> will be zero.
28131 </para></entry>
28132 </row>
28134 <row>
28135 <entry role="func_table_entry"><para role="func_signature">
28136 <indexterm>
28137 <primary>pg_get_wal_summarizer_state</primary>
28138 </indexterm>
28139 <function>pg_get_wal_summarizer_state</function> ()
28140 <returnvalue>record</returnvalue>
28141 ( <parameter>summarized_tli</parameter> <type>bigint</type>,
28142 <parameter>summarized_lsn</parameter> <type>pg_lsn</type>,
28143 <parameter>pending_lsn</parameter> <type>pg_lsn</type>,
28144 <parameter>summarizer_pid</parameter> <type>int</type> )
28145 </para>
28146 <para>
28147 Returns information about the progress of the WAL summarizer. If the
28148 WAL summarizer has never run since the instance was started, then
28149 <literal>summarized_tli</literal> and <literal>summarized_lsn</literal>
28150 will be <literal>0</literal> and <literal>0/0</literal> respectively;
28151 otherwise, they will be the TLI and ending LSN of the last WAL summary
28152 file written to disk. If the WAL summarizer is currently running,
28153 <literal>pending_lsn</literal> will be the ending LSN of the last
28154 record that it has consumed, which must always be greater than or
28155 equal to <literal>summarized_lsn</literal>; if the WAL summarizer is
28156 not running, it will be equal to <literal>summarized_lsn</literal>.
28157 <literal>summarizer_pid</literal> is the PID of the WAL summarizer
28158 process, if it is running, and otherwise NULL.
28159 </para>
28160 <para>
28161 As a special exception, the WAL summarizer will refuse to generate
28162 WAL summary files if run on WAL generated under
28163 <literal>wal_level=minimal</literal>, since such summaries would be
28164 unsafe to use as the basis for an incremental backup. In this case,
28165 the fields above will continue to advance as if summaries were being
28166 generated, but nothing will be written to disk. Once the summarizer
28167 reaches WAL generated while <literal>wal_level</literal> was set
28168 to <literal>replica</literal> or higher, it will resume writing
28169 summaries to disk.
28170 </para></entry>
28171 </row>
28172 </tbody>
28173 </tgroup>
28174 </table>
28176 </sect2>
28178 </sect1>
28180 <sect1 id="functions-admin">
28181 <title>System Administration Functions</title>
28183 <para>
28184 The functions described in this section are used to control and
28185 monitor a <productname>PostgreSQL</productname> installation.
28186 </para>
28188 <sect2 id="functions-admin-set">
28189 <title>Configuration Settings Functions</title>
28191 <indexterm>
28192 <primary>SET</primary>
28193 </indexterm>
28195 <indexterm>
28196 <primary>SHOW</primary>
28197 </indexterm>
28199 <indexterm>
28200 <primary>configuration</primary>
28201 <secondary sortas="server">of the server</secondary>
28202 <tertiary>functions</tertiary>
28203 </indexterm>
28205 <para>
28206 <xref linkend="functions-admin-set-table"/> shows the functions
28207 available to query and alter run-time configuration parameters.
28208 </para>
28210 <table id="functions-admin-set-table">
28211 <title>Configuration Settings Functions</title>
28212 <tgroup cols="1">
28213 <thead>
28214 <row>
28215 <entry role="func_table_entry"><para role="func_signature">
28216 Function
28217 </para>
28218 <para>
28219 Description
28220 </para>
28221 <para>
28222 Example(s)
28223 </para></entry>
28224 </row>
28225 </thead>
28227 <tbody>
28228 <row>
28229 <entry role="func_table_entry"><para role="func_signature">
28230 <indexterm>
28231 <primary>current_setting</primary>
28232 </indexterm>
28233 <function>current_setting</function> ( <parameter>setting_name</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
28234 <returnvalue>text</returnvalue>
28235 </para>
28236 <para>
28237 Returns the current value of the
28238 setting <parameter>setting_name</parameter>. If there is no such
28239 setting, <function>current_setting</function> throws an error
28240 unless <parameter>missing_ok</parameter> is supplied and
28241 is <literal>true</literal> (in which case NULL is returned).
28242 This function corresponds to
28243 the <acronym>SQL</acronym> command <xref linkend="sql-show"/>.
28244 </para>
28245 <para>
28246 <literal>current_setting('datestyle')</literal>
28247 <returnvalue>ISO, MDY</returnvalue>
28248 </para></entry>
28249 </row>
28251 <row>
28252 <entry role="func_table_entry"><para role="func_signature">
28253 <indexterm>
28254 <primary>set_config</primary>
28255 </indexterm>
28256 <function>set_config</function> (
28257 <parameter>setting_name</parameter> <type>text</type>,
28258 <parameter>new_value</parameter> <type>text</type>,
28259 <parameter>is_local</parameter> <type>boolean</type> )
28260 <returnvalue>text</returnvalue>
28261 </para>
28262 <para>
28263 Sets the parameter <parameter>setting_name</parameter>
28264 to <parameter>new_value</parameter>, and returns that value.
28265 If <parameter>is_local</parameter> is <literal>true</literal>, the new
28266 value will only apply during the current transaction. If you want the
28267 new value to apply for the rest of the current session,
28268 use <literal>false</literal> instead. This function corresponds to
28269 the SQL command <xref linkend="sql-set"/>.
28270 </para>
28271 <para>
28272 <literal>set_config('log_statement_stats', 'off', false)</literal>
28273 <returnvalue>off</returnvalue>
28274 </para></entry>
28275 </row>
28276 </tbody>
28277 </tgroup>
28278 </table>
28280 </sect2>
28282 <sect2 id="functions-admin-signal">
28283 <title>Server Signaling Functions</title>
28285 <indexterm>
28286 <primary>signal</primary>
28287 <secondary sortas="backend">backend processes</secondary>
28288 </indexterm>
28290 <para>
28291 The functions shown in <xref
28292 linkend="functions-admin-signal-table"/> send control signals to
28293 other server processes. Use of these functions is restricted to
28294 superusers by default but access may be granted to others using
28295 <command>GRANT</command>, with noted exceptions.
28296 </para>
28298 <para>
28299 Each of these functions returns <literal>true</literal> if
28300 the signal was successfully sent and <literal>false</literal>
28301 if sending the signal failed.
28302 </para>
28304 <table id="functions-admin-signal-table">
28305 <title>Server Signaling Functions</title>
28306 <tgroup cols="1">
28307 <thead>
28308 <row>
28309 <entry role="func_table_entry"><para role="func_signature">
28310 Function
28311 </para>
28312 <para>
28313 Description
28314 </para></entry>
28315 </row>
28316 </thead>
28318 <tbody>
28319 <row>
28320 <entry role="func_table_entry"><para role="func_signature">
28321 <indexterm>
28322 <primary>pg_cancel_backend</primary>
28323 </indexterm>
28324 <function>pg_cancel_backend</function> ( <parameter>pid</parameter> <type>integer</type> )
28325 <returnvalue>boolean</returnvalue>
28326 </para>
28327 <para>
28328 Cancels the current query of the session whose backend process has the
28329 specified process ID. This is also allowed if the
28330 calling role is a member of the role whose backend is being canceled or
28331 the calling role has privileges of <literal>pg_signal_backend</literal>,
28332 however only superusers can cancel superuser backends.
28333 As an exception, roles with privileges of
28334 <literal>pg_signal_autovacuum_worker</literal> are permitted to
28335 cancel autovacuum worker processes, which are otherwise considered
28336 superuser backends.
28337 </para></entry>
28338 </row>
28340 <row>
28341 <entry role="func_table_entry"><para role="func_signature">
28342 <indexterm>
28343 <primary>pg_log_backend_memory_contexts</primary>
28344 </indexterm>
28345 <function>pg_log_backend_memory_contexts</function> ( <parameter>pid</parameter> <type>integer</type> )
28346 <returnvalue>boolean</returnvalue>
28347 </para>
28348 <para>
28349 Requests to log the memory contexts of the backend with the
28350 specified process ID. This function can send the request to
28351 backends and auxiliary processes except logger. These memory contexts
28352 will be logged at
28353 <literal>LOG</literal> message level. They will appear in
28354 the server log based on the log configuration set
28355 (see <xref linkend="runtime-config-logging"/> for more information),
28356 but will not be sent to the client regardless of
28357 <xref linkend="guc-client-min-messages"/>.
28358 </para></entry>
28359 </row>
28361 <row>
28362 <entry role="func_table_entry"><para role="func_signature">
28363 <indexterm>
28364 <primary>pg_reload_conf</primary>
28365 </indexterm>
28366 <function>pg_reload_conf</function> ()
28367 <returnvalue>boolean</returnvalue>
28368 </para>
28369 <para>
28370 Causes all processes of the <productname>PostgreSQL</productname>
28371 server to reload their configuration files. (This is initiated by
28372 sending a <systemitem>SIGHUP</systemitem> signal to the postmaster
28373 process, which in turn sends <systemitem>SIGHUP</systemitem> to each
28374 of its children.) You can use the
28375 <link linkend="view-pg-file-settings"><structname>pg_file_settings</structname></link>,
28376 <link linkend="view-pg-hba-file-rules"><structname>pg_hba_file_rules</structname></link> and
28377 <link linkend="view-pg-ident-file-mappings"><structname>pg_ident_file_mappings</structname></link> views
28378 to check the configuration files for possible errors, before reloading.
28379 </para></entry>
28380 </row>
28382 <row>
28383 <entry role="func_table_entry"><para role="func_signature">
28384 <indexterm>
28385 <primary>pg_rotate_logfile</primary>
28386 </indexterm>
28387 <function>pg_rotate_logfile</function> ()
28388 <returnvalue>boolean</returnvalue>
28389 </para>
28390 <para>
28391 Signals the log-file manager to switch to a new output file
28392 immediately. This works only when the built-in log collector is
28393 running, since otherwise there is no log-file manager subprocess.
28394 </para></entry>
28395 </row>
28397 <row>
28398 <entry role="func_table_entry"><para role="func_signature">
28399 <indexterm>
28400 <primary>pg_terminate_backend</primary>
28401 </indexterm>
28402 <function>pg_terminate_backend</function> ( <parameter>pid</parameter> <type>integer</type>, <parameter>timeout</parameter> <type>bigint</type> <literal>DEFAULT</literal> <literal>0</literal> )
28403 <returnvalue>boolean</returnvalue>
28404 </para>
28405 <para>
28406 Terminates the session whose backend process has the
28407 specified process ID. This is also allowed if the calling role
28408 is a member of the role whose backend is being terminated or the
28409 calling role has privileges of <literal>pg_signal_backend</literal>,
28410 however only superusers can terminate superuser backends.
28411 As an exception, roles with privileges of
28412 <literal>pg_signal_autovacuum_worker</literal> are permitted to
28413 terminate autovacuum worker processes, which are otherwise considered
28414 superuser backends.
28415 </para>
28416 <para>
28417 If <parameter>timeout</parameter> is not specified or zero, this
28418 function returns <literal>true</literal> whether the process actually
28419 terminates or not, indicating only that the sending of the signal was
28420 successful. If the <parameter>timeout</parameter> is specified (in
28421 milliseconds) and greater than zero, the function waits until the
28422 process is actually terminated or until the given time has passed. If
28423 the process is terminated, the function
28424 returns <literal>true</literal>. On timeout, a warning is emitted and
28425 <literal>false</literal> is returned.
28426 </para></entry>
28427 </row>
28428 </tbody>
28429 </tgroup>
28430 </table>
28432 <para>
28433 <function>pg_cancel_backend</function> and <function>pg_terminate_backend</function>
28434 send signals (<systemitem>SIGINT</systemitem> or <systemitem>SIGTERM</systemitem>
28435 respectively) to backend processes identified by process ID.
28436 The process ID of an active backend can be found from
28437 the <structfield>pid</structfield> column of the
28438 <structname>pg_stat_activity</structname> view, or by listing the
28439 <command>postgres</command> processes on the server (using
28440 <application>ps</application> on Unix or the <application>Task
28441 Manager</application> on <productname>Windows</productname>).
28442 The role of an active backend can be found from the
28443 <structfield>usename</structfield> column of the
28444 <structname>pg_stat_activity</structname> view.
28445 </para>
28447 <para>
28448 <function>pg_log_backend_memory_contexts</function> can be used
28449 to log the memory contexts of a backend process. For example:
28450 <programlisting>
28451 postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid());
28452 pg_log_backend_memory_contexts
28453 --------------------------------
28455 (1 row)
28456 </programlisting>
28457 One message for each memory context will be logged. For example:
28458 <screen>
28459 LOG: logging memory contexts of PID 10377
28460 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid());
28461 LOG: level: 0; TopMemoryContext: 80800 total in 6 blocks; 14432 free (5 chunks); 66368 used
28462 LOG: level: 1; pgstat TabStatusArray lookup hash table: 8192 total in 1 blocks; 1408 free (0 chunks); 6784 used
28463 LOG: level: 1; TopTransactionContext: 8192 total in 1 blocks; 7720 free (1 chunks); 472 used
28464 LOG: level: 1; RowDescriptionContext: 8192 total in 1 blocks; 6880 free (0 chunks); 1312 used
28465 LOG: level: 1; MessageContext: 16384 total in 2 blocks; 5152 free (0 chunks); 11232 used
28466 LOG: level: 1; Operator class cache: 8192 total in 1 blocks; 512 free (0 chunks); 7680 used
28467 LOG: level: 1; smgr relation table: 16384 total in 2 blocks; 4544 free (3 chunks); 11840 used
28468 LOG: level: 1; TransactionAbortContext: 32768 total in 1 blocks; 32504 free (0 chunks); 264 used
28470 LOG: level: 1; ErrorContext: 8192 total in 1 blocks; 7928 free (3 chunks); 264 used
28471 LOG: Grand total: 1651920 bytes in 201 blocks; 622360 free (88 chunks); 1029560 used
28472 </screen>
28473 If there are more than 100 child contexts under the same parent, the first
28474 100 child contexts are logged, along with a summary of the remaining contexts.
28475 Note that frequent calls to this function could incur significant overhead,
28476 because it may generate a large number of log messages.
28477 </para>
28479 </sect2>
28481 <sect2 id="functions-admin-backup">
28482 <title>Backup Control Functions</title>
28484 <indexterm>
28485 <primary>backup</primary>
28486 </indexterm>
28488 <para>
28489 The functions shown in <xref
28490 linkend="functions-admin-backup-table"/> assist in making on-line backups.
28491 These functions cannot be executed during recovery (except
28492 <function>pg_backup_start</function>,
28493 <function>pg_backup_stop</function>,
28494 and <function>pg_wal_lsn_diff</function>).
28495 </para>
28497 <para>
28498 For details about proper usage of these functions, see
28499 <xref linkend="continuous-archiving"/>.
28500 </para>
28502 <table id="functions-admin-backup-table">
28503 <title>Backup Control Functions</title>
28504 <tgroup cols="1">
28505 <thead>
28506 <row>
28507 <entry role="func_table_entry"><para role="func_signature">
28508 Function
28509 </para>
28510 <para>
28511 Description
28512 </para></entry>
28513 </row>
28514 </thead>
28516 <tbody>
28517 <row>
28518 <entry role="func_table_entry"><para role="func_signature">
28519 <indexterm>
28520 <primary>pg_create_restore_point</primary>
28521 </indexterm>
28522 <function>pg_create_restore_point</function> ( <parameter>name</parameter> <type>text</type> )
28523 <returnvalue>pg_lsn</returnvalue>
28524 </para>
28525 <para>
28526 Creates a named marker record in the write-ahead log that can later be
28527 used as a recovery target, and returns the corresponding write-ahead
28528 log location. The given name can then be used with
28529 <xref linkend="guc-recovery-target-name"/> to specify the point up to
28530 which recovery will proceed. Avoid creating multiple restore points
28531 with the same name, since recovery will stop at the first one whose
28532 name matches the recovery target.
28533 </para>
28534 <para>
28535 This function is restricted to superusers by default, but other users
28536 can be granted EXECUTE to run the function.
28537 </para></entry>
28538 </row>
28540 <row>
28541 <entry role="func_table_entry"><para role="func_signature">
28542 <indexterm>
28543 <primary>pg_current_wal_flush_lsn</primary>
28544 </indexterm>
28545 <function>pg_current_wal_flush_lsn</function> ()
28546 <returnvalue>pg_lsn</returnvalue>
28547 </para>
28548 <para>
28549 Returns the current write-ahead log flush location (see notes below).
28550 </para></entry>
28551 </row>
28553 <row>
28554 <entry role="func_table_entry"><para role="func_signature">
28555 <indexterm>
28556 <primary>pg_current_wal_insert_lsn</primary>
28557 </indexterm>
28558 <function>pg_current_wal_insert_lsn</function> ()
28559 <returnvalue>pg_lsn</returnvalue>
28560 </para>
28561 <para>
28562 Returns the current write-ahead log insert location (see notes below).
28563 </para></entry>
28564 </row>
28566 <row>
28567 <entry role="func_table_entry"><para role="func_signature">
28568 <indexterm>
28569 <primary>pg_current_wal_lsn</primary>
28570 </indexterm>
28571 <function>pg_current_wal_lsn</function> ()
28572 <returnvalue>pg_lsn</returnvalue>
28573 </para>
28574 <para>
28575 Returns the current write-ahead log write location (see notes below).
28576 </para></entry>
28577 </row>
28579 <row>
28580 <entry role="func_table_entry"><para role="func_signature">
28581 <indexterm>
28582 <primary>pg_backup_start</primary>
28583 </indexterm>
28584 <function>pg_backup_start</function> (
28585 <parameter>label</parameter> <type>text</type>
28586 <optional>, <parameter>fast</parameter> <type>boolean</type>
28587 </optional> )
28588 <returnvalue>pg_lsn</returnvalue>
28589 </para>
28590 <para>
28591 Prepares the server to begin an on-line backup. The only required
28592 parameter is an arbitrary user-defined label for the backup.
28593 (Typically this would be the name under which the backup dump file
28594 will be stored.)
28595 If the optional second parameter is given as <literal>true</literal>,
28596 it specifies executing <function>pg_backup_start</function> as quickly
28597 as possible. This forces an immediate checkpoint which will cause a
28598 spike in I/O operations, slowing any concurrently executing queries.
28599 </para>
28600 <para>
28601 This function is restricted to superusers by default, but other users
28602 can be granted EXECUTE to run the function.
28603 </para></entry>
28604 </row>
28606 <row>
28607 <entry role="func_table_entry"><para role="func_signature">
28608 <indexterm>
28609 <primary>pg_backup_stop</primary>
28610 </indexterm>
28611 <function>pg_backup_stop</function> (
28612 <optional><parameter>wait_for_archive</parameter> <type>boolean</type>
28613 </optional> )
28614 <returnvalue>record</returnvalue>
28615 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
28616 <parameter>labelfile</parameter> <type>text</type>,
28617 <parameter>spcmapfile</parameter> <type>text</type> )
28618 </para>
28619 <para>
28620 Finishes performing an on-line backup. The desired contents of the
28621 backup label file and the tablespace map file are returned as part of
28622 the result of the function and must be written to files in the
28623 backup area. These files must not be written to the live data directory
28624 (doing so will cause PostgreSQL to fail to restart in the event of a
28625 crash).
28626 </para>
28627 <para>
28628 There is an optional parameter of type <type>boolean</type>.
28629 If false, the function will return immediately after the backup is
28630 completed, without waiting for WAL to be archived. This behavior is
28631 only useful with backup software that independently monitors WAL
28632 archiving. Otherwise, WAL required to make the backup consistent might
28633 be missing and make the backup useless. By default or when this
28634 parameter is true, <function>pg_backup_stop</function> will wait for
28635 WAL to be archived when archiving is enabled. (On a standby, this
28636 means that it will wait only when <varname>archive_mode</varname> =
28637 <literal>always</literal>. If write activity on the primary is low,
28638 it may be useful to run <function>pg_switch_wal</function> on the
28639 primary in order to trigger an immediate segment switch.)
28640 </para>
28641 <para>
28642 When executed on a primary, this function also creates a backup
28643 history file in the write-ahead log archive area. The history file
28644 includes the label given to <function>pg_backup_start</function>, the
28645 starting and ending write-ahead log locations for the backup, and the
28646 starting and ending times of the backup. After recording the ending
28647 location, the current write-ahead log insertion point is automatically
28648 advanced to the next write-ahead log file, so that the ending
28649 write-ahead log file can be archived immediately to complete the
28650 backup.
28651 </para>
28652 <para>
28653 The result of the function is a single record.
28654 The <parameter>lsn</parameter> column holds the backup's ending
28655 write-ahead log location (which again can be ignored). The second
28656 column returns the contents of the backup label file, and the third
28657 column returns the contents of the tablespace map file. These must be
28658 stored as part of the backup and are required as part of the restore
28659 process.
28660 </para>
28661 <para>
28662 This function is restricted to superusers by default, but other users
28663 can be granted EXECUTE to run the function.
28664 </para></entry>
28665 </row>
28667 <row>
28668 <entry role="func_table_entry"><para role="func_signature">
28669 <indexterm>
28670 <primary>pg_switch_wal</primary>
28671 </indexterm>
28672 <function>pg_switch_wal</function> ()
28673 <returnvalue>pg_lsn</returnvalue>
28674 </para>
28675 <para>
28676 Forces the server to switch to a new write-ahead log file, which
28677 allows the current file to be archived (assuming you are using
28678 continuous archiving). The result is the ending write-ahead log
28679 location plus 1 within the just-completed write-ahead log file. If
28680 there has been no write-ahead log activity since the last write-ahead
28681 log switch, <function>pg_switch_wal</function> does nothing and
28682 returns the start location of the write-ahead log file currently in
28683 use.
28684 </para>
28685 <para>
28686 This function is restricted to superusers by default, but other users
28687 can be granted EXECUTE to run the function.
28688 </para></entry>
28689 </row>
28691 <row>
28692 <entry role="func_table_entry"><para role="func_signature">
28693 <indexterm>
28694 <primary>pg_walfile_name</primary>
28695 </indexterm>
28696 <function>pg_walfile_name</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
28697 <returnvalue>text</returnvalue>
28698 </para>
28699 <para>
28700 Converts a write-ahead log location to the name of the WAL file
28701 holding that location.
28702 </para></entry>
28703 </row>
28705 <row>
28706 <entry role="func_table_entry"><para role="func_signature">
28707 <indexterm>
28708 <primary>pg_walfile_name_offset</primary>
28709 </indexterm>
28710 <function>pg_walfile_name_offset</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
28711 <returnvalue>record</returnvalue>
28712 ( <parameter>file_name</parameter> <type>text</type>,
28713 <parameter>file_offset</parameter> <type>integer</type> )
28714 </para>
28715 <para>
28716 Converts a write-ahead log location to a WAL file name and byte offset
28717 within that file.
28718 </para></entry>
28719 </row>
28721 <row>
28722 <entry role="func_table_entry"><para role="func_signature">
28723 <indexterm>
28724 <primary>pg_split_walfile_name</primary>
28725 </indexterm>
28726 <function>pg_split_walfile_name</function> ( <parameter>file_name</parameter> <type>text</type> )
28727 <returnvalue>record</returnvalue>
28728 ( <parameter>segment_number</parameter> <type>numeric</type>,
28729 <parameter>timeline_id</parameter> <type>bigint</type> )
28730 </para>
28731 <para>
28732 Extracts the sequence number and timeline ID from a WAL file
28733 name.
28734 </para></entry>
28735 </row>
28737 <row>
28738 <entry role="func_table_entry"><para role="func_signature">
28739 <indexterm>
28740 <primary>pg_wal_lsn_diff</primary>
28741 </indexterm>
28742 <function>pg_wal_lsn_diff</function> ( <parameter>lsn1</parameter> <type>pg_lsn</type>, <parameter>lsn2</parameter> <type>pg_lsn</type> )
28743 <returnvalue>numeric</returnvalue>
28744 </para>
28745 <para>
28746 Calculates the difference in bytes (<parameter>lsn1</parameter> - <parameter>lsn2</parameter>) between two write-ahead log
28747 locations. This can be used
28748 with <structname>pg_stat_replication</structname> or some of the
28749 functions shown in <xref linkend="functions-admin-backup-table"/> to
28750 get the replication lag.
28751 </para></entry>
28752 </row>
28753 </tbody>
28754 </tgroup>
28755 </table>
28757 <para>
28758 <function>pg_current_wal_lsn</function> displays the current write-ahead
28759 log write location in the same format used by the above functions.
28760 Similarly, <function>pg_current_wal_insert_lsn</function> displays the
28761 current write-ahead log insertion location
28762 and <function>pg_current_wal_flush_lsn</function> displays the current
28763 write-ahead log flush location. The insertion location is
28764 the <quote>logical</quote> end of the write-ahead log at any instant,
28765 while the write location is the end of what has actually been written out
28766 from the server's internal buffers, and the flush location is the last
28767 location known to be written to durable storage. The write location is the
28768 end of what can be examined from outside the server, and is usually what
28769 you want if you are interested in archiving partially-complete write-ahead
28770 log files. The insertion and flush locations are made available primarily
28771 for server debugging purposes. These are all read-only operations and do
28772 not require superuser permissions.
28773 </para>
28775 <para>
28776 You can use <function>pg_walfile_name_offset</function> to extract the
28777 corresponding write-ahead log file name and byte offset from
28778 a <type>pg_lsn</type> value. For example:
28779 <programlisting>
28780 postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn);
28781 file_name | file_offset
28782 --------------------------+-------------
28783 00000001000000000000000D | 4039624
28784 (1 row)
28785 </programlisting>
28786 Similarly, <function>pg_walfile_name</function> extracts just the write-ahead log file name.
28787 </para>
28789 <para>
28790 <function>pg_split_walfile_name</function> is useful to compute a
28791 <acronym>LSN</acronym> from a file offset and WAL file name, for example:
28792 <programlisting>
28793 postgres=# \set file_name '000000010000000100C000AB'
28794 postgres=# \set offset 256
28795 postgres=# SELECT '0/0'::pg_lsn + pd.segment_number * ps.setting::int + :offset AS lsn
28796 FROM pg_split_walfile_name(:'file_name') pd,
28797 pg_show_all_settings() ps
28798 WHERE ps.name = 'wal_segment_size';
28800 ---------------
28801 C001/AB000100
28802 (1 row)
28803 </programlisting>
28804 </para>
28806 </sect2>
28808 <sect2 id="functions-recovery-control">
28809 <title>Recovery Control Functions</title>
28811 <para>
28812 The functions shown in <xref
28813 linkend="functions-recovery-info-table"/> provide information
28814 about the current status of a standby server.
28815 These functions may be executed both during recovery and in normal running.
28816 </para>
28818 <table id="functions-recovery-info-table">
28819 <title>Recovery Information Functions</title>
28820 <tgroup cols="1">
28821 <thead>
28822 <row>
28823 <entry role="func_table_entry"><para role="func_signature">
28824 Function
28825 </para>
28826 <para>
28827 Description
28828 </para></entry>
28829 </row>
28830 </thead>
28832 <tbody>
28833 <row>
28834 <entry role="func_table_entry"><para role="func_signature">
28835 <indexterm>
28836 <primary>pg_is_in_recovery</primary>
28837 </indexterm>
28838 <function>pg_is_in_recovery</function> ()
28839 <returnvalue>boolean</returnvalue>
28840 </para>
28841 <para>
28842 Returns true if recovery is still in progress.
28843 </para></entry>
28844 </row>
28846 <row>
28847 <entry role="func_table_entry"><para role="func_signature">
28848 <indexterm>
28849 <primary>pg_last_wal_receive_lsn</primary>
28850 </indexterm>
28851 <function>pg_last_wal_receive_lsn</function> ()
28852 <returnvalue>pg_lsn</returnvalue>
28853 </para>
28854 <para>
28855 Returns the last write-ahead log location that has been received and
28856 synced to disk by streaming replication. While streaming replication
28857 is in progress this will increase monotonically. If recovery has
28858 completed then this will remain static at the location of the last WAL
28859 record received and synced to disk during recovery. If streaming
28860 replication is disabled, or if it has not yet started, the function
28861 returns <literal>NULL</literal>.
28862 </para></entry>
28863 </row>
28865 <row>
28866 <entry role="func_table_entry"><para role="func_signature">
28867 <indexterm>
28868 <primary>pg_last_wal_replay_lsn</primary>
28869 </indexterm>
28870 <function>pg_last_wal_replay_lsn</function> ()
28871 <returnvalue>pg_lsn</returnvalue>
28872 </para>
28873 <para>
28874 Returns the last write-ahead log location that has been replayed
28875 during recovery. If recovery is still in progress this will increase
28876 monotonically. If recovery has completed then this will remain
28877 static at the location of the last WAL record applied during recovery.
28878 When the server has been started normally without recovery, the
28879 function returns <literal>NULL</literal>.
28880 </para></entry>
28881 </row>
28883 <row>
28884 <entry role="func_table_entry"><para role="func_signature">
28885 <indexterm>
28886 <primary>pg_last_xact_replay_timestamp</primary>
28887 </indexterm>
28888 <function>pg_last_xact_replay_timestamp</function> ()
28889 <returnvalue>timestamp with time zone</returnvalue>
28890 </para>
28891 <para>
28892 Returns the time stamp of the last transaction replayed during
28893 recovery. This is the time at which the commit or abort WAL record
28894 for that transaction was generated on the primary. If no transactions
28895 have been replayed during recovery, the function
28896 returns <literal>NULL</literal>. Otherwise, if recovery is still in
28897 progress this will increase monotonically. If recovery has completed
28898 then this will remain static at the time of the last transaction
28899 applied during recovery. When the server has been started normally
28900 without recovery, the function returns <literal>NULL</literal>.
28901 </para></entry>
28902 </row>
28904 <row>
28905 <entry role="func_table_entry"><para role="func_signature">
28906 <indexterm>
28907 <primary>pg_get_wal_resource_managers</primary>
28908 </indexterm>
28909 <function>pg_get_wal_resource_managers</function> ()
28910 <returnvalue>setof record</returnvalue>
28911 ( <parameter>rm_id</parameter> <type>integer</type>,
28912 <parameter>rm_name</parameter> <type>text</type>,
28913 <parameter>rm_builtin</parameter> <type>boolean</type> )
28914 </para>
28915 <para>
28916 Returns the currently-loaded WAL resource managers in the system. The
28917 column <parameter>rm_builtin</parameter> indicates whether it's a
28918 built-in resource manager, or a custom resource manager loaded by an
28919 extension.
28920 </para></entry>
28921 </row>
28922 </tbody>
28923 </tgroup>
28924 </table>
28926 <para>
28927 The functions shown in <xref
28928 linkend="functions-recovery-control-table"/> control the progress of recovery.
28929 These functions may be executed only during recovery.
28930 </para>
28932 <table id="functions-recovery-control-table">
28933 <title>Recovery Control Functions</title>
28934 <tgroup cols="1">
28935 <thead>
28936 <row>
28937 <entry role="func_table_entry"><para role="func_signature">
28938 Function
28939 </para>
28940 <para>
28941 Description
28942 </para></entry>
28943 </row>
28944 </thead>
28946 <tbody>
28947 <row>
28948 <entry role="func_table_entry"><para role="func_signature">
28949 <indexterm>
28950 <primary>pg_is_wal_replay_paused</primary>
28951 </indexterm>
28952 <function>pg_is_wal_replay_paused</function> ()
28953 <returnvalue>boolean</returnvalue>
28954 </para>
28955 <para>
28956 Returns true if recovery pause is requested.
28957 </para></entry>
28958 </row>
28960 <row>
28961 <entry role="func_table_entry"><para role="func_signature">
28962 <indexterm>
28963 <primary>pg_get_wal_replay_pause_state</primary>
28964 </indexterm>
28965 <function>pg_get_wal_replay_pause_state</function> ()
28966 <returnvalue>text</returnvalue>
28967 </para>
28968 <para>
28969 Returns recovery pause state. The return values are <literal>
28970 not paused</literal> if pause is not requested, <literal>
28971 pause requested</literal> if pause is requested but recovery is
28972 not yet paused, and <literal>paused</literal> if the recovery is
28973 actually paused.
28974 </para></entry>
28975 </row>
28977 <row>
28978 <entry role="func_table_entry"><para role="func_signature">
28979 <indexterm>
28980 <primary>pg_promote</primary>
28981 </indexterm>
28982 <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> )
28983 <returnvalue>boolean</returnvalue>
28984 </para>
28985 <para>
28986 Promotes a standby server to primary status.
28987 With <parameter>wait</parameter> set to <literal>true</literal> (the
28988 default), the function waits until promotion is completed
28989 or <parameter>wait_seconds</parameter> seconds have passed, and
28990 returns <literal>true</literal> if promotion is successful
28991 and <literal>false</literal> otherwise.
28992 If <parameter>wait</parameter> is set to <literal>false</literal>, the
28993 function returns <literal>true</literal> immediately after sending a
28994 <literal>SIGUSR1</literal> signal to the postmaster to trigger
28995 promotion.
28996 </para>
28997 <para>
28998 This function is restricted to superusers by default, but other users
28999 can be granted EXECUTE to run the function.
29000 </para></entry>
29001 </row>
29003 <row>
29004 <entry role="func_table_entry"><para role="func_signature">
29005 <indexterm>
29006 <primary>pg_wal_replay_pause</primary>
29007 </indexterm>
29008 <function>pg_wal_replay_pause</function> ()
29009 <returnvalue>void</returnvalue>
29010 </para>
29011 <para>
29012 Request to pause recovery. A request doesn't mean that recovery stops
29013 right away. If you want a guarantee that recovery is actually paused,
29014 you need to check for the recovery pause state returned by
29015 <function>pg_get_wal_replay_pause_state()</function>. Note that
29016 <function>pg_is_wal_replay_paused()</function> returns whether a request
29017 is made. While recovery is paused, no further database changes are applied.
29018 If hot standby is active, all new queries will see the same consistent
29019 snapshot of the database, and no further query conflicts will be generated
29020 until recovery is resumed.
29021 </para>
29022 <para>
29023 This function is restricted to superusers by default, but other users
29024 can be granted EXECUTE to run the function.
29025 </para></entry>
29026 </row>
29028 <row>
29029 <entry role="func_table_entry"><para role="func_signature">
29030 <indexterm>
29031 <primary>pg_wal_replay_resume</primary>
29032 </indexterm>
29033 <function>pg_wal_replay_resume</function> ()
29034 <returnvalue>void</returnvalue>
29035 </para>
29036 <para>
29037 Restarts recovery if it was paused.
29038 </para>
29039 <para>
29040 This function is restricted to superusers by default, but other users
29041 can be granted EXECUTE to run the function.
29042 </para></entry>
29043 </row>
29044 </tbody>
29045 </tgroup>
29046 </table>
29048 <para>
29049 <function>pg_wal_replay_pause</function> and
29050 <function>pg_wal_replay_resume</function> cannot be executed while
29051 a promotion is ongoing. If a promotion is triggered while recovery
29052 is paused, the paused state ends and promotion continues.
29053 </para>
29055 <para>
29056 If streaming replication is disabled, the paused state may continue
29057 indefinitely without a problem. If streaming replication is in
29058 progress then WAL records will continue to be received, which will
29059 eventually fill available disk space, depending upon the duration of
29060 the pause, the rate of WAL generation and available disk space.
29061 </para>
29063 </sect2>
29065 <sect2 id="functions-snapshot-synchronization">
29066 <title>Snapshot Synchronization Functions</title>
29068 <para>
29069 <productname>PostgreSQL</productname> allows database sessions to synchronize their
29070 snapshots. A <firstterm>snapshot</firstterm> determines which data is visible to the
29071 transaction that is using the snapshot. Synchronized snapshots are
29072 necessary when two or more sessions need to see identical content in the
29073 database. If two sessions just start their transactions independently,
29074 there is always a possibility that some third transaction commits
29075 between the executions of the two <command>START TRANSACTION</command> commands,
29076 so that one session sees the effects of that transaction and the other
29077 does not.
29078 </para>
29080 <para>
29081 To solve this problem, <productname>PostgreSQL</productname> allows a transaction to
29082 <firstterm>export</firstterm> the snapshot it is using. As long as the exporting
29083 transaction remains open, other transactions can <firstterm>import</firstterm> its
29084 snapshot, and thereby be guaranteed that they see exactly the same view
29085 of the database that the first transaction sees. But note that any
29086 database changes made by any one of these transactions remain invisible
29087 to the other transactions, as is usual for changes made by uncommitted
29088 transactions. So the transactions are synchronized with respect to
29089 pre-existing data, but act normally for changes they make themselves.
29090 </para>
29092 <para>
29093 Snapshots are exported with the <function>pg_export_snapshot</function> function,
29094 shown in <xref linkend="functions-snapshot-synchronization-table"/>, and
29095 imported with the <xref linkend="sql-set-transaction"/> command.
29096 </para>
29098 <table id="functions-snapshot-synchronization-table">
29099 <title>Snapshot Synchronization Functions</title>
29100 <tgroup cols="1">
29101 <thead>
29102 <row>
29103 <entry role="func_table_entry"><para role="func_signature">
29104 Function
29105 </para>
29106 <para>
29107 Description
29108 </para></entry>
29109 </row>
29110 </thead>
29112 <tbody>
29113 <row>
29114 <entry role="func_table_entry"><para role="func_signature">
29115 <indexterm>
29116 <primary>pg_export_snapshot</primary>
29117 </indexterm>
29118 <function>pg_export_snapshot</function> ()
29119 <returnvalue>text</returnvalue>
29120 </para>
29121 <para>
29122 Saves the transaction's current snapshot and returns
29123 a <type>text</type> string identifying the snapshot. This string must
29124 be passed (outside the database) to clients that want to import the
29125 snapshot. The snapshot is available for import only until the end of
29126 the transaction that exported it.
29127 </para>
29128 <para>
29129 A transaction can export more than one snapshot, if needed. Note that
29130 doing so is only useful in <literal>READ COMMITTED</literal>
29131 transactions, since in <literal>REPEATABLE READ</literal> and higher
29132 isolation levels, transactions use the same snapshot throughout their
29133 lifetime. Once a transaction has exported any snapshots, it cannot be
29134 prepared with <xref linkend="sql-prepare-transaction"/>.
29135 </para></entry>
29136 </row>
29137 <row>
29138 <entry role="func_table_entry"><para role="func_signature">
29139 <indexterm>
29140 <primary>pg_log_standby_snapshot</primary>
29141 </indexterm>
29142 <function>pg_log_standby_snapshot</function> ()
29143 <returnvalue>pg_lsn</returnvalue>
29144 </para>
29145 <para>
29146 Take a snapshot of running transactions and write it to WAL, without
29147 having to wait for bgwriter or checkpointer to log one. This is useful
29148 for logical decoding on standby, as logical slot creation has to wait
29149 until such a record is replayed on the standby.
29150 </para></entry>
29151 </row>
29152 </tbody>
29153 </tgroup>
29154 </table>
29156 </sect2>
29158 <sect2 id="functions-replication">
29159 <title>Replication Management Functions</title>
29161 <para>
29162 The functions shown
29163 in <xref linkend="functions-replication-table"/> are for
29164 controlling and interacting with replication features.
29165 See <xref linkend="streaming-replication"/>,
29166 <xref linkend="streaming-replication-slots"/>, and
29167 <xref linkend="replication-origins"/>
29168 for information about the underlying features.
29169 Use of functions for replication origin is only allowed to the
29170 superuser by default, but may be allowed to other users by using the
29171 <literal>GRANT</literal> command.
29172 Use of functions for replication slots is restricted to superusers
29173 and users having <literal>REPLICATION</literal> privilege.
29174 </para>
29176 <para>
29177 Many of these functions have equivalent commands in the replication
29178 protocol; see <xref linkend="protocol-replication"/>.
29179 </para>
29181 <para>
29182 The functions described in
29183 <xref linkend="functions-admin-backup"/>,
29184 <xref linkend="functions-recovery-control"/>, and
29185 <xref linkend="functions-snapshot-synchronization"/>
29186 are also relevant for replication.
29187 </para>
29189 <table id="functions-replication-table">
29190 <title>Replication Management Functions</title>
29191 <tgroup cols="1">
29192 <thead>
29193 <row>
29194 <entry role="func_table_entry"><para role="func_signature">
29195 Function
29196 </para>
29197 <para>
29198 Description
29199 </para></entry>
29200 </row>
29201 </thead>
29203 <tbody>
29204 <row>
29205 <entry role="func_table_entry"><para role="func_signature">
29206 <indexterm>
29207 <primary>pg_create_physical_replication_slot</primary>
29208 </indexterm>
29209 <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> )
29210 <returnvalue>record</returnvalue>
29211 ( <parameter>slot_name</parameter> <type>name</type>,
29212 <parameter>lsn</parameter> <type>pg_lsn</type> )
29213 </para>
29214 <para>
29215 Creates a new physical replication slot named
29216 <parameter>slot_name</parameter>. The optional second parameter,
29217 when <literal>true</literal>, specifies that the <acronym>LSN</acronym> for this
29218 replication slot be reserved immediately; otherwise
29219 the <acronym>LSN</acronym> is reserved on first connection from a streaming
29220 replication client. Streaming changes from a physical slot is only
29221 possible with the streaming-replication protocol &mdash;
29222 see <xref linkend="protocol-replication"/>. The optional third
29223 parameter, <parameter>temporary</parameter>, when set to true, specifies that
29224 the slot should not be permanently stored to disk and is only meant
29225 for use by the current session. Temporary slots are also
29226 released upon any error. This function corresponds
29227 to the replication protocol command <literal>CREATE_REPLICATION_SLOT
29228 ... PHYSICAL</literal>.
29229 </para></entry>
29230 </row>
29232 <row>
29233 <entry role="func_table_entry"><para role="func_signature">
29234 <indexterm>
29235 <primary>pg_drop_replication_slot</primary>
29236 </indexterm>
29237 <function>pg_drop_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type> )
29238 <returnvalue>void</returnvalue>
29239 </para>
29240 <para>
29241 Drops the physical or logical replication slot
29242 named <parameter>slot_name</parameter>. Same as replication protocol
29243 command <literal>DROP_REPLICATION_SLOT</literal>. For logical slots, this must
29244 be called while connected to the same database the slot was created on.
29245 </para></entry>
29246 </row>
29248 <row>
29249 <entry id="pg-create-logical-replication-slot" role="func_table_entry"><para role="func_signature">
29250 <indexterm>
29251 <primary>pg_create_logical_replication_slot</primary>
29252 </indexterm>
29253 <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>, <parameter>failover</parameter> <type>boolean</type> </optional> )
29254 <returnvalue>record</returnvalue>
29255 ( <parameter>slot_name</parameter> <type>name</type>,
29256 <parameter>lsn</parameter> <type>pg_lsn</type> )
29257 </para>
29258 <para>
29259 Creates a new logical (decoding) replication slot named
29260 <parameter>slot_name</parameter> using the output plugin
29261 <parameter>plugin</parameter>. The optional third
29262 parameter, <parameter>temporary</parameter>, when set to true, specifies that
29263 the slot should not be permanently stored to disk and is only meant
29264 for use by the current session. Temporary slots are also
29265 released upon any error. The optional fourth parameter,
29266 <parameter>twophase</parameter>, when set to true, specifies
29267 that the decoding of prepared transactions is enabled for this
29268 slot. The optional fifth parameter,
29269 <parameter>failover</parameter>, when set to true,
29270 specifies that this slot is enabled to be synced to the
29271 standbys so that logical replication can be resumed after
29272 failover. A call to this function has the same effect as
29273 the replication protocol command
29274 <literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>.
29275 </para></entry>
29276 </row>
29278 <row>
29279 <entry role="func_table_entry"><para role="func_signature">
29280 <indexterm>
29281 <primary>pg_copy_physical_replication_slot</primary>
29282 </indexterm>
29283 <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> )
29284 <returnvalue>record</returnvalue>
29285 ( <parameter>slot_name</parameter> <type>name</type>,
29286 <parameter>lsn</parameter> <type>pg_lsn</type> )
29287 </para>
29288 <para>
29289 Copies an existing physical replication slot named <parameter>src_slot_name</parameter>
29290 to a physical replication slot named <parameter>dst_slot_name</parameter>.
29291 The copied physical slot starts to reserve WAL from the same <acronym>LSN</acronym> as the
29292 source slot.
29293 <parameter>temporary</parameter> is optional. If <parameter>temporary</parameter>
29294 is omitted, the same value as the source slot is used.
29295 </para></entry>
29296 </row>
29298 <row>
29299 <entry role="func_table_entry"><para role="func_signature">
29300 <indexterm>
29301 <primary>pg_copy_logical_replication_slot</primary>
29302 </indexterm>
29303 <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> )
29304 <returnvalue>record</returnvalue>
29305 ( <parameter>slot_name</parameter> <type>name</type>,
29306 <parameter>lsn</parameter> <type>pg_lsn</type> )
29307 </para>
29308 <para>
29309 Copies an existing logical replication slot
29310 named <parameter>src_slot_name</parameter> to a logical replication
29311 slot named <parameter>dst_slot_name</parameter>, optionally changing
29312 the output plugin and persistence. The copied logical slot starts
29313 from the same <acronym>LSN</acronym> as the source logical slot. Both
29314 <parameter>temporary</parameter> and <parameter>plugin</parameter> are
29315 optional; if they are omitted, the values of the source slot are used.
29316 </para></entry>
29317 </row>
29319 <row>
29320 <entry id="pg-logical-slot-get-changes" role="func_table_entry"><para role="func_signature">
29321 <indexterm>
29322 <primary>pg_logical_slot_get_changes</primary>
29323 </indexterm>
29324 <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> )
29325 <returnvalue>setof record</returnvalue>
29326 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
29327 <parameter>xid</parameter> <type>xid</type>,
29328 <parameter>data</parameter> <type>text</type> )
29329 </para>
29330 <para>
29331 Returns changes in the slot <parameter>slot_name</parameter>, starting
29332 from the point from which changes have been consumed last. If
29333 <parameter>upto_lsn</parameter>
29334 and <parameter>upto_nchanges</parameter> are NULL,
29335 logical decoding will continue until end of WAL. If
29336 <parameter>upto_lsn</parameter> is non-NULL, decoding will include only
29337 those transactions which commit prior to the specified LSN. If
29338 <parameter>upto_nchanges</parameter> is non-NULL, decoding will
29339 stop when the number of rows produced by decoding exceeds
29340 the specified value. Note, however, that the actual number of
29341 rows returned may be larger, since this limit is only checked after
29342 adding the rows produced when decoding each new transaction commit.
29343 If the specified slot is a logical failover slot then the function will
29344 not return until all physical slots specified in
29345 <link linkend="guc-synchronized-standby-slots"><varname>synchronized_standby_slots</varname></link>
29346 have confirmed WAL receipt.
29347 </para></entry>
29348 </row>
29350 <row>
29351 <entry id="pg-logical-slot-peek-changes" role="func_table_entry"><para role="func_signature">
29352 <indexterm>
29353 <primary>pg_logical_slot_peek_changes</primary>
29354 </indexterm>
29355 <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> )
29356 <returnvalue>setof record</returnvalue>
29357 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
29358 <parameter>xid</parameter> <type>xid</type>,
29359 <parameter>data</parameter> <type>text</type> )
29360 </para>
29361 <para>
29362 Behaves just like
29363 the <function>pg_logical_slot_get_changes()</function> function,
29364 except that changes are not consumed; that is, they will be returned
29365 again on future calls.
29366 </para></entry>
29367 </row>
29369 <row>
29370 <entry role="func_table_entry"><para role="func_signature">
29371 <indexterm>
29372 <primary>pg_logical_slot_get_binary_changes</primary>
29373 </indexterm>
29374 <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> )
29375 <returnvalue>setof record</returnvalue>
29376 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
29377 <parameter>xid</parameter> <type>xid</type>,
29378 <parameter>data</parameter> <type>bytea</type> )
29379 </para>
29380 <para>
29381 Behaves just like
29382 the <function>pg_logical_slot_get_changes()</function> function,
29383 except that changes are returned as <type>bytea</type>.
29384 </para></entry>
29385 </row>
29387 <row>
29388 <entry role="func_table_entry"><para role="func_signature">
29389 <indexterm>
29390 <primary>pg_logical_slot_peek_binary_changes</primary>
29391 </indexterm>
29392 <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> )
29393 <returnvalue>setof record</returnvalue>
29394 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
29395 <parameter>xid</parameter> <type>xid</type>,
29396 <parameter>data</parameter> <type>bytea</type> )
29397 </para>
29398 <para>
29399 Behaves just like
29400 the <function>pg_logical_slot_peek_changes()</function> function,
29401 except that changes are returned as <type>bytea</type>.
29402 </para></entry>
29403 </row>
29405 <row>
29406 <entry id="pg-replication-slot-advance" role="func_table_entry"><para role="func_signature">
29407 <indexterm>
29408 <primary>pg_replication_slot_advance</primary>
29409 </indexterm>
29410 <function>pg_replication_slot_advance</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type> )
29411 <returnvalue>record</returnvalue>
29412 ( <parameter>slot_name</parameter> <type>name</type>,
29413 <parameter>end_lsn</parameter> <type>pg_lsn</type> )
29414 </para>
29415 <para>
29416 Advances the current confirmed position of a replication slot named
29417 <parameter>slot_name</parameter>. The slot will not be moved backwards,
29418 and it will not be moved beyond the current insert location. Returns
29419 the name of the slot and the actual position that it was advanced to.
29420 The updated slot position information is written out at the next
29421 checkpoint if any advancing is done. So in the event of a crash, the
29422 slot may return to an earlier position. If the specified slot is a
29423 logical failover slot then the function will not return until all
29424 physical slots specified in
29425 <link linkend="guc-synchronized-standby-slots"><varname>synchronized_standby_slots</varname></link>
29426 have confirmed WAL receipt.
29427 </para></entry>
29428 </row>
29430 <row>
29431 <entry id="pg-replication-origin-create" role="func_table_entry"><para role="func_signature">
29432 <indexterm>
29433 <primary>pg_replication_origin_create</primary>
29434 </indexterm>
29435 <function>pg_replication_origin_create</function> ( <parameter>node_name</parameter> <type>text</type> )
29436 <returnvalue>oid</returnvalue>
29437 </para>
29438 <para>
29439 Creates a replication origin with the given external
29440 name, and returns the internal ID assigned to it.
29441 </para></entry>
29442 </row>
29444 <row>
29445 <entry id="pg-replication-origin-drop" role="func_table_entry"><para role="func_signature">
29446 <indexterm>
29447 <primary>pg_replication_origin_drop</primary>
29448 </indexterm>
29449 <function>pg_replication_origin_drop</function> ( <parameter>node_name</parameter> <type>text</type> )
29450 <returnvalue>void</returnvalue>
29451 </para>
29452 <para>
29453 Deletes a previously-created replication origin, including any
29454 associated replay progress.
29455 </para></entry>
29456 </row>
29458 <row>
29459 <entry role="func_table_entry"><para role="func_signature">
29460 <indexterm>
29461 <primary>pg_replication_origin_oid</primary>
29462 </indexterm>
29463 <function>pg_replication_origin_oid</function> ( <parameter>node_name</parameter> <type>text</type> )
29464 <returnvalue>oid</returnvalue>
29465 </para>
29466 <para>
29467 Looks up a replication origin by name and returns the internal ID. If
29468 no such replication origin is found, <literal>NULL</literal> is
29469 returned.
29470 </para></entry>
29471 </row>
29473 <row>
29474 <entry id="pg-replication-origin-session-setup" role="func_table_entry"><para role="func_signature">
29475 <indexterm>
29476 <primary>pg_replication_origin_session_setup</primary>
29477 </indexterm>
29478 <function>pg_replication_origin_session_setup</function> ( <parameter>node_name</parameter> <type>text</type> )
29479 <returnvalue>void</returnvalue>
29480 </para>
29481 <para>
29482 Marks the current session as replaying from the given
29483 origin, allowing replay progress to be tracked.
29484 Can only be used if no origin is currently selected.
29485 Use <function>pg_replication_origin_session_reset</function> to undo.
29486 </para></entry>
29487 </row>
29489 <row>
29490 <entry role="func_table_entry"><para role="func_signature">
29491 <indexterm>
29492 <primary>pg_replication_origin_session_reset</primary>
29493 </indexterm>
29494 <function>pg_replication_origin_session_reset</function> ()
29495 <returnvalue>void</returnvalue>
29496 </para>
29497 <para>
29498 Cancels the effects
29499 of <function>pg_replication_origin_session_setup()</function>.
29500 </para></entry>
29501 </row>
29503 <row>
29504 <entry role="func_table_entry"><para role="func_signature">
29505 <indexterm>
29506 <primary>pg_replication_origin_session_is_setup</primary>
29507 </indexterm>
29508 <function>pg_replication_origin_session_is_setup</function> ()
29509 <returnvalue>boolean</returnvalue>
29510 </para>
29511 <para>
29512 Returns true if a replication origin has been selected in the
29513 current session.
29514 </para></entry>
29515 </row>
29517 <row>
29518 <entry id="pg-replication-origin-session-progress" role="func_table_entry"><para role="func_signature">
29519 <indexterm>
29520 <primary>pg_replication_origin_session_progress</primary>
29521 </indexterm>
29522 <function>pg_replication_origin_session_progress</function> ( <parameter>flush</parameter> <type>boolean</type> )
29523 <returnvalue>pg_lsn</returnvalue>
29524 </para>
29525 <para>
29526 Returns the replay location for the replication origin selected in
29527 the current session. The parameter <parameter>flush</parameter>
29528 determines whether the corresponding local transaction will be
29529 guaranteed to have been flushed to disk or not.
29530 </para></entry>
29531 </row>
29533 <row>
29534 <entry id="pg-replication-origin-xact-setup" role="func_table_entry"><para role="func_signature">
29535 <indexterm>
29536 <primary>pg_replication_origin_xact_setup</primary>
29537 </indexterm>
29538 <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> )
29539 <returnvalue>void</returnvalue>
29540 </para>
29541 <para>
29542 Marks the current transaction as replaying a transaction that has
29543 committed at the given <acronym>LSN</acronym> and timestamp. Can
29544 only be called when a replication origin has been selected
29545 using <function>pg_replication_origin_session_setup</function>.
29546 </para></entry>
29547 </row>
29549 <row>
29550 <entry id="pg-replication-origin-xact-reset" role="func_table_entry"><para role="func_signature">
29551 <indexterm>
29552 <primary>pg_replication_origin_xact_reset</primary>
29553 </indexterm>
29554 <function>pg_replication_origin_xact_reset</function> ()
29555 <returnvalue>void</returnvalue>
29556 </para>
29557 <para>
29558 Cancels the effects of
29559 <function>pg_replication_origin_xact_setup()</function>.
29560 </para></entry>
29561 </row>
29563 <row>
29564 <entry id="pg-replication-origin-advance" role="func_table_entry"><para role="func_signature">
29565 <indexterm>
29566 <primary>pg_replication_origin_advance</primary>
29567 </indexterm>
29568 <function>pg_replication_origin_advance</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>lsn</parameter> <type>pg_lsn</type> )
29569 <returnvalue>void</returnvalue>
29570 </para>
29571 <para>
29572 Sets replication progress for the given node to the given
29573 location. This is primarily useful for setting up the initial
29574 location, or setting a new location after configuration changes and
29575 similar. Be aware that careless use of this function can lead to
29576 inconsistently replicated data.
29577 </para></entry>
29578 </row>
29580 <row>
29581 <entry id="pg-replication-origin-progress" role="func_table_entry"><para role="func_signature">
29582 <indexterm>
29583 <primary>pg_replication_origin_progress</primary>
29584 </indexterm>
29585 <function>pg_replication_origin_progress</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>boolean</type> )
29586 <returnvalue>pg_lsn</returnvalue>
29587 </para>
29588 <para>
29589 Returns the replay location for the given replication origin. The
29590 parameter <parameter>flush</parameter> determines whether the
29591 corresponding local transaction will be guaranteed to have been
29592 flushed to disk or not.
29593 </para></entry>
29594 </row>
29596 <row>
29597 <entry id="pg-logical-emit-message" role="func_table_entry"><para role="func_signature">
29598 <indexterm>
29599 <primary>pg_logical_emit_message</primary>
29600 </indexterm>
29601 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>text</type> <optional>, <parameter>flush</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>false</literal></optional> )
29602 <returnvalue>pg_lsn</returnvalue>
29603 </para>
29604 <para role="func_signature">
29605 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>bytea</type> <optional>, <parameter>flush</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>false</literal></optional> )
29606 <returnvalue>pg_lsn</returnvalue>
29607 </para>
29608 <para>
29609 Emits a logical decoding message. This can be used to pass generic
29610 messages to logical decoding plugins through
29611 WAL. The <parameter>transactional</parameter> parameter specifies if
29612 the message should be part of the current transaction, or if it should
29613 be written immediately and decoded as soon as the logical decoder
29614 reads the record. The <parameter>prefix</parameter> parameter is a
29615 textual prefix that can be used by logical decoding plugins to easily
29616 recognize messages that are interesting for them.
29617 The <parameter>content</parameter> parameter is the content of the
29618 message, given either in text or binary form.
29619 The <parameter>flush</parameter> parameter (default set to
29620 <literal>false</literal>) controls if the message is immediately
29621 flushed to WAL or not. <parameter>flush</parameter> has no effect
29622 with <parameter>transactional</parameter>, as the message's WAL
29623 record is flushed along with its transaction.
29624 </para></entry>
29625 </row>
29627 <row>
29628 <entry id="pg-sync-replication-slots" role="func_table_entry"><para role="func_signature">
29629 <indexterm>
29630 <primary>pg_sync_replication_slots</primary>
29631 </indexterm>
29632 <function>pg_sync_replication_slots</function> ()
29633 <returnvalue>void</returnvalue>
29634 </para>
29635 <para>
29636 Synchronize the logical failover replication slots from the primary
29637 server to the standby server. This function can only be executed on the
29638 standby server. Temporary synced slots, if any, cannot be used for
29639 logical decoding and must be dropped after promotion. See
29640 <xref linkend="logicaldecoding-replication-slots-synchronization"/> for details.
29641 Note that this function cannot be executed if
29642 <link linkend="guc-sync-replication-slots"><varname>
29643 sync_replication_slots</varname></link> is enabled and the slotsync
29644 worker is already running to perform the synchronization of slots.
29645 </para>
29647 <caution>
29648 <para>
29649 If, after executing the function,
29650 <link linkend="guc-hot-standby-feedback">
29651 <varname>hot_standby_feedback</varname></link> is disabled on
29652 the standby or the physical slot configured in
29653 <link linkend="guc-primary-slot-name">
29654 <varname>primary_slot_name</varname></link> is
29655 removed, then it is possible that the necessary rows of the
29656 synchronized slot will be removed by the VACUUM process on the primary
29657 server, resulting in the synchronized slot becoming invalidated.
29658 </para>
29659 </caution>
29660 </entry>
29661 </row>
29663 </tbody>
29664 </tgroup>
29665 </table>
29667 </sect2>
29669 <sect2 id="functions-admin-dbobject">
29670 <title>Database Object Management Functions</title>
29672 <para>
29673 The functions shown in <xref linkend="functions-admin-dbsize"/> calculate
29674 the disk space usage of database objects, or assist in presentation
29675 or understanding of usage results. <literal>bigint</literal> results
29676 are measured in bytes. If an OID that does
29677 not represent an existing object is passed to one of these
29678 functions, <literal>NULL</literal> is returned.
29679 </para>
29681 <table id="functions-admin-dbsize">
29682 <title>Database Object Size Functions</title>
29683 <tgroup cols="1">
29684 <thead>
29685 <row>
29686 <entry role="func_table_entry"><para role="func_signature">
29687 Function
29688 </para>
29689 <para>
29690 Description
29691 </para></entry>
29692 </row>
29693 </thead>
29695 <tbody>
29696 <row>
29697 <entry role="func_table_entry"><para role="func_signature">
29698 <indexterm>
29699 <primary>pg_column_size</primary>
29700 </indexterm>
29701 <function>pg_column_size</function> ( <type>"any"</type> )
29702 <returnvalue>integer</returnvalue>
29703 </para>
29704 <para>
29705 Shows the number of bytes used to store any individual data value. If
29706 applied directly to a table column value, this reflects any
29707 compression that was done.
29708 </para></entry>
29709 </row>
29711 <row>
29712 <entry role="func_table_entry"><para role="func_signature">
29713 <indexterm>
29714 <primary>pg_column_compression</primary>
29715 </indexterm>
29716 <function>pg_column_compression</function> ( <type>"any"</type> )
29717 <returnvalue>text</returnvalue>
29718 </para>
29719 <para>
29720 Shows the compression algorithm that was used to compress
29721 an individual variable-length value. Returns <literal>NULL</literal>
29722 if the value is not compressed.
29723 </para></entry>
29724 </row>
29726 <row>
29727 <entry role="func_table_entry"><para role="func_signature">
29728 <indexterm>
29729 <primary>pg_column_toast_chunk_id</primary>
29730 </indexterm>
29731 <function>pg_column_toast_chunk_id</function> ( <type>"any"</type> )
29732 <returnvalue>oid</returnvalue>
29733 </para>
29734 <para>
29735 Shows the <structfield>chunk_id</structfield> of an on-disk
29736 <acronym>TOAST</acronym>ed value. Returns <literal>NULL</literal>
29737 if the value is un-<acronym>TOAST</acronym>ed or not on-disk. See
29738 <xref linkend="storage-toast"/> for more information about
29739 <acronym>TOAST</acronym>.
29740 </para></entry>
29741 </row>
29743 <row>
29744 <entry role="func_table_entry"><para role="func_signature">
29745 <indexterm>
29746 <primary>pg_database_size</primary>
29747 </indexterm>
29748 <function>pg_database_size</function> ( <type>name</type> )
29749 <returnvalue>bigint</returnvalue>
29750 </para>
29751 <para role="func_signature">
29752 <function>pg_database_size</function> ( <type>oid</type> )
29753 <returnvalue>bigint</returnvalue>
29754 </para>
29755 <para>
29756 Computes the total disk space used by the database with the specified
29757 name or OID. To use this function, you must
29758 have <literal>CONNECT</literal> privilege on the specified database
29759 (which is granted by default) or have privileges of
29760 the <literal>pg_read_all_stats</literal> role.
29761 </para></entry>
29762 </row>
29764 <row>
29765 <entry role="func_table_entry"><para role="func_signature">
29766 <indexterm>
29767 <primary>pg_indexes_size</primary>
29768 </indexterm>
29769 <function>pg_indexes_size</function> ( <type>regclass</type> )
29770 <returnvalue>bigint</returnvalue>
29771 </para>
29772 <para>
29773 Computes the total disk space used by indexes attached to the
29774 specified table.
29775 </para></entry>
29776 </row>
29778 <row>
29779 <entry role="func_table_entry"><para role="func_signature">
29780 <indexterm>
29781 <primary>pg_relation_size</primary>
29782 </indexterm>
29783 <function>pg_relation_size</function> ( <parameter>relation</parameter> <type>regclass</type> <optional>, <parameter>fork</parameter> <type>text</type> </optional> )
29784 <returnvalue>bigint</returnvalue>
29785 </para>
29786 <para>
29787 Computes the disk space used by one <quote>fork</quote> of the
29788 specified relation. (Note that for most purposes it is more
29789 convenient to use the higher-level
29790 functions <function>pg_total_relation_size</function>
29791 or <function>pg_table_size</function>, which sum the sizes of all
29792 forks.) With one argument, this returns the size of the main data
29793 fork of the relation. The second argument can be provided to specify
29794 which fork to examine:
29795 <itemizedlist spacing="compact">
29796 <listitem>
29797 <para>
29798 <literal>main</literal> returns the size of the main
29799 data fork of the relation.
29800 </para>
29801 </listitem>
29802 <listitem>
29803 <para>
29804 <literal>fsm</literal> returns the size of the Free Space Map
29805 (see <xref linkend="storage-fsm"/>) associated with the relation.
29806 </para>
29807 </listitem>
29808 <listitem>
29809 <para>
29810 <literal>vm</literal> returns the size of the Visibility Map
29811 (see <xref linkend="storage-vm"/>) associated with the relation.
29812 </para>
29813 </listitem>
29814 <listitem>
29815 <para>
29816 <literal>init</literal> returns the size of the initialization
29817 fork, if any, associated with the relation.
29818 </para>
29819 </listitem>
29820 </itemizedlist>
29821 </para></entry>
29822 </row>
29824 <row>
29825 <entry role="func_table_entry"><para role="func_signature">
29826 <indexterm>
29827 <primary>pg_size_bytes</primary>
29828 </indexterm>
29829 <function>pg_size_bytes</function> ( <type>text</type> )
29830 <returnvalue>bigint</returnvalue>
29831 </para>
29832 <para>
29833 Converts a size in human-readable format (as returned
29834 by <function>pg_size_pretty</function>) into bytes. Valid units are
29835 <literal>bytes</literal>, <literal>B</literal>, <literal>kB</literal>,
29836 <literal>MB</literal>, <literal>GB</literal>, <literal>TB</literal>,
29837 and <literal>PB</literal>.
29838 </para></entry>
29839 </row>
29841 <row>
29842 <entry role="func_table_entry"><para role="func_signature">
29843 <indexterm>
29844 <primary>pg_size_pretty</primary>
29845 </indexterm>
29846 <function>pg_size_pretty</function> ( <type>bigint</type> )
29847 <returnvalue>text</returnvalue>
29848 </para>
29849 <para role="func_signature">
29850 <function>pg_size_pretty</function> ( <type>numeric</type> )
29851 <returnvalue>text</returnvalue>
29852 </para>
29853 <para>
29854 Converts a size in bytes into a more easily human-readable format with
29855 size units (bytes, kB, MB, GB, TB, or PB as appropriate). Note that the
29856 units are powers of 2 rather than powers of 10, so 1kB is 1024 bytes,
29857 1MB is 1024<superscript>2</superscript> = 1048576 bytes, and so on.
29858 </para></entry>
29859 </row>
29861 <row>
29862 <entry role="func_table_entry"><para role="func_signature">
29863 <indexterm>
29864 <primary>pg_table_size</primary>
29865 </indexterm>
29866 <function>pg_table_size</function> ( <type>regclass</type> )
29867 <returnvalue>bigint</returnvalue>
29868 </para>
29869 <para>
29870 Computes the disk space used by the specified table, excluding indexes
29871 (but including its TOAST table if any, free space map, and visibility
29872 map).
29873 </para></entry>
29874 </row>
29876 <row>
29877 <entry role="func_table_entry"><para role="func_signature">
29878 <indexterm>
29879 <primary>pg_tablespace_size</primary>
29880 </indexterm>
29881 <function>pg_tablespace_size</function> ( <type>name</type> )
29882 <returnvalue>bigint</returnvalue>
29883 </para>
29884 <para role="func_signature">
29885 <function>pg_tablespace_size</function> ( <type>oid</type> )
29886 <returnvalue>bigint</returnvalue>
29887 </para>
29888 <para>
29889 Computes the total disk space used in the tablespace with the
29890 specified name or OID. To use this function, you must
29891 have <literal>CREATE</literal> privilege on the specified tablespace
29892 or have privileges of the <literal>pg_read_all_stats</literal> role,
29893 unless it is the default tablespace for the current database.
29894 </para></entry>
29895 </row>
29897 <row>
29898 <entry role="func_table_entry"><para role="func_signature">
29899 <indexterm>
29900 <primary>pg_total_relation_size</primary>
29901 </indexterm>
29902 <function>pg_total_relation_size</function> ( <type>regclass</type> )
29903 <returnvalue>bigint</returnvalue>
29904 </para>
29905 <para>
29906 Computes the total disk space used by the specified table, including
29907 all indexes and <acronym>TOAST</acronym> data. The result is
29908 equivalent to <function>pg_table_size</function>
29909 <literal>+</literal> <function>pg_indexes_size</function>.
29910 </para></entry>
29911 </row>
29912 </tbody>
29913 </tgroup>
29914 </table>
29916 <para>
29917 The functions above that operate on tables or indexes accept a
29918 <type>regclass</type> argument, which is simply the OID of the table or index
29919 in the <structname>pg_class</structname> system catalog. You do not have to look up
29920 the OID by hand, however, since the <type>regclass</type> data type's input
29921 converter will do the work for you. See <xref linkend="datatype-oid"/>
29922 for details.
29923 </para>
29925 <para>
29926 The functions shown in <xref linkend="functions-admin-dblocation"/> assist
29927 in identifying the specific disk files associated with database objects.
29928 </para>
29930 <table id="functions-admin-dblocation">
29931 <title>Database Object Location Functions</title>
29932 <tgroup cols="1">
29933 <thead>
29934 <row>
29935 <entry role="func_table_entry"><para role="func_signature">
29936 Function
29937 </para>
29938 <para>
29939 Description
29940 </para></entry>
29941 </row>
29942 </thead>
29944 <tbody>
29945 <row>
29946 <entry role="func_table_entry"><para role="func_signature">
29947 <indexterm>
29948 <primary>pg_relation_filenode</primary>
29949 </indexterm>
29950 <function>pg_relation_filenode</function> ( <parameter>relation</parameter> <type>regclass</type> )
29951 <returnvalue>oid</returnvalue>
29952 </para>
29953 <para>
29954 Returns the <quote>filenode</quote> number currently assigned to the
29955 specified relation. The filenode is the base component of the file
29956 name(s) used for the relation (see
29957 <xref linkend="storage-file-layout"/> for more information).
29958 For most relations the result is the same as
29959 <structname>pg_class</structname>.<structfield>relfilenode</structfield>,
29960 but for certain system catalogs <structfield>relfilenode</structfield>
29961 is zero and this function must be used to get the correct value. The
29962 function returns NULL if passed a relation that does not have storage,
29963 such as a view.
29964 </para></entry>
29965 </row>
29967 <row>
29968 <entry role="func_table_entry"><para role="func_signature">
29969 <indexterm>
29970 <primary>pg_relation_filepath</primary>
29971 </indexterm>
29972 <function>pg_relation_filepath</function> ( <parameter>relation</parameter> <type>regclass</type> )
29973 <returnvalue>text</returnvalue>
29974 </para>
29975 <para>
29976 Returns the entire file path name (relative to the database cluster's
29977 data directory, <varname>PGDATA</varname>) of the relation.
29978 </para></entry>
29979 </row>
29981 <row>
29982 <entry role="func_table_entry"><para role="func_signature">
29983 <indexterm>
29984 <primary>pg_filenode_relation</primary>
29985 </indexterm>
29986 <function>pg_filenode_relation</function> ( <parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type> )
29987 <returnvalue>regclass</returnvalue>
29988 </para>
29989 <para>
29990 Returns a relation's OID given the tablespace OID and filenode it is
29991 stored under. This is essentially the inverse mapping of
29992 <function>pg_relation_filepath</function>. For a relation in the
29993 database's default tablespace, the tablespace can be specified as zero.
29994 Returns <literal>NULL</literal> if no relation in the current database
29995 is associated with the given values.
29996 </para></entry>
29997 </row>
29998 </tbody>
29999 </tgroup>
30000 </table>
30002 <para>
30003 <xref linkend="functions-admin-collation"/> lists functions used to manage
30004 collations.
30005 </para>
30007 <table id="functions-admin-collation">
30008 <title>Collation Management Functions</title>
30009 <tgroup cols="1">
30010 <thead>
30011 <row>
30012 <entry role="func_table_entry"><para role="func_signature">
30013 Function
30014 </para>
30015 <para>
30016 Description
30017 </para></entry>
30018 </row>
30019 </thead>
30021 <tbody>
30022 <row>
30023 <entry role="func_table_entry"><para role="func_signature">
30024 <indexterm>
30025 <primary>pg_collation_actual_version</primary>
30026 </indexterm>
30027 <function>pg_collation_actual_version</function> ( <type>oid</type> )
30028 <returnvalue>text</returnvalue>
30029 </para>
30030 <para>
30031 Returns the actual version of the collation object as it is currently
30032 installed in the operating system. If this is different from the
30033 value in
30034 <structname>pg_collation</structname>.<structfield>collversion</structfield>,
30035 then objects depending on the collation might need to be rebuilt. See
30036 also <xref linkend="sql-altercollation"/>.
30037 </para></entry>
30038 </row>
30040 <row>
30041 <entry role="func_table_entry"><para role="func_signature">
30042 <indexterm>
30043 <primary>pg_database_collation_actual_version</primary>
30044 </indexterm>
30045 <function>pg_database_collation_actual_version</function> ( <type>oid</type> )
30046 <returnvalue>text</returnvalue>
30047 </para>
30048 <para>
30049 Returns the actual version of the database's collation as it is currently
30050 installed in the operating system. If this is different from the
30051 value in
30052 <structname>pg_database</structname>.<structfield>datcollversion</structfield>,
30053 then objects depending on the collation might need to be rebuilt. See
30054 also <xref linkend="sql-alterdatabase"/>.
30055 </para></entry>
30056 </row>
30058 <row>
30059 <entry role="func_table_entry"><para role="func_signature">
30060 <indexterm>
30061 <primary>pg_import_system_collations</primary>
30062 </indexterm>
30063 <function>pg_import_system_collations</function> ( <parameter>schema</parameter> <type>regnamespace</type> )
30064 <returnvalue>integer</returnvalue>
30065 </para>
30066 <para>
30067 Adds collations to the system
30068 catalog <structname>pg_collation</structname> based on all the locales
30069 it finds in the operating system. This is
30070 what <command>initdb</command> uses; see
30071 <xref linkend="collation-managing"/> for more details. If additional
30072 locales are installed into the operating system later on, this
30073 function can be run again to add collations for the new locales.
30074 Locales that match existing entries
30075 in <structname>pg_collation</structname> will be skipped. (But
30076 collation objects based on locales that are no longer present in the
30077 operating system are not removed by this function.)
30078 The <parameter>schema</parameter> parameter would typically
30079 be <literal>pg_catalog</literal>, but that is not a requirement; the
30080 collations could be installed into some other schema as well. The
30081 function returns the number of new collation objects it created.
30082 Use of this function is restricted to superusers.
30083 </para></entry>
30084 </row>
30085 </tbody>
30086 </tgroup>
30087 </table>
30089 <para>
30090 <xref linkend="functions-admin-statsmod"/> lists functions used to
30091 manipulate statistics.
30092 These functions cannot be executed during recovery.
30093 <warning>
30094 <para>
30095 Changes made by these statistics manipulation functions are likely to be
30096 overwritten by <link linkend="autovacuum">autovacuum</link> (or manual
30097 <command>VACUUM</command> or <command>ANALYZE</command>) and should be
30098 considered temporary.
30099 </para>
30100 </warning>
30101 </para>
30103 <table id="functions-admin-statsmod">
30104 <title>Database Object Statistics Manipulation Functions</title>
30105 <tgroup cols="1">
30106 <thead>
30107 <row>
30108 <entry role="func_table_entry"><para role="func_signature">
30109 Function
30110 </para>
30111 <para>
30112 Description
30113 </para></entry>
30114 </row>
30115 </thead>
30117 <tbody>
30118 <row>
30119 <entry role="func_table_entry">
30120 <para role="func_signature">
30121 <indexterm>
30122 <primary>pg_set_relation_stats</primary>
30123 </indexterm>
30124 <function>pg_set_relation_stats</function> (
30125 <parameter>relation</parameter> <type>regclass</type>
30126 <optional>, <parameter>relpages</parameter> <type>integer</type></optional>
30127 <optional>, <parameter>reltuples</parameter> <type>real</type></optional>
30128 <optional>, <parameter>relallvisible</parameter> <type>integer</type></optional> )
30129 <returnvalue>void</returnvalue>
30130 </para>
30131 <para>
30132 Updates relation-level statistics for the given relation to the
30133 specified values. The parameters correspond to columns in <link
30134 linkend="catalog-pg-class"><structname>pg_class</structname></link>. Unspecified
30135 or <literal>NULL</literal> values leave the setting unchanged.
30136 </para>
30137 <para>
30138 Ordinarily, these statistics are collected automatically or updated
30139 as a part of <xref linkend="sql-vacuum"/> or <xref
30140 linkend="sql-analyze"/>, so it's not necessary to call this
30141 function. However, it may be useful when testing the effects of
30142 statistics on the planner to understand or anticipate plan changes.
30143 </para>
30144 <para>
30145 The caller must have the <literal>MAINTAIN</literal> privilege on
30146 the table or be the owner of the database.
30147 </para>
30148 <para>
30149 The value of <structfield>relpages</structfield> must be greater than
30150 or equal to <literal>-1</literal>,
30151 <structfield>reltuples</structfield> must be greater than or equal to
30152 <literal>-1.0</literal>, and <structfield>relallvisible</structfield>
30153 must be greater than or equal to <literal>0</literal>.
30154 </para>
30155 </entry>
30156 </row>
30158 <row>
30159 <entry role="func_table_entry">
30160 <para role="func_signature">
30161 <indexterm>
30162 <primary>pg_clear_relation_stats</primary>
30163 </indexterm>
30164 <function>pg_clear_relation_stats</function> ( <parameter>relation</parameter> <type>regclass</type> )
30165 <returnvalue>void</returnvalue>
30166 </para>
30167 <para>
30168 Clears table-level statistics for the given relation, as though the
30169 table was newly created.
30170 </para>
30171 <para>
30172 The caller must have the <literal>MAINTAIN</literal> privilege on
30173 the table or be the owner of the database.
30174 </para>
30175 </entry>
30176 </row>
30178 <row>
30179 <entry role="func_table_entry"><para role="func_signature">
30180 <indexterm>
30181 <primary>pg_restore_relation_stats</primary>
30182 </indexterm>
30183 <function>pg_restore_relation_stats</function> (
30184 <literal>VARIADIC</literal> <parameter>kwargs</parameter> <type>"any"</type> )
30185 <returnvalue>boolean</returnvalue>
30186 </para>
30187 <para>
30188 Similar to <function>pg_set_relation_stats()</function>, but intended
30189 for bulk restore of relation statistics. The tracked statistics may
30190 change from version to version, so the primary purpose of this
30191 function is to maintain a consistent function signature to avoid
30192 errors when restoring statistics from previous versions.
30193 </para>
30194 <para>
30195 To match the behavior of <xref linkend="sql-vacuum"/> and <xref
30196 linkend="sql-analyze"/> when updating relation statistics,
30197 <function>pg_restore_relation_stats()</function> does not follow MVCC
30198 transactional semantics (see <xref linkend="mvcc"/>). New relation
30199 statistics may be durable even if the transaction aborts, and the
30200 changes are not isolated from other transactions.
30201 </para>
30202 <para>
30203 Arguments are passed as pairs of <replaceable>argname</replaceable>
30204 and <replaceable>argvalue</replaceable>, where
30205 <replaceable>argname</replaceable> corresponds to a named argument in
30206 <function>pg_set_relation_stats()</function> and
30207 <replaceable>argvalue</replaceable> is of the corresponding type.
30208 </para>
30209 <para>
30210 Additionally, this function supports argument name
30211 <literal>version</literal> of type <type>integer</type>, which
30212 specifies the version from which the statistics originated, improving
30213 interpretation of older statistics.
30214 </para>
30215 <para>
30216 For example, to set the <structname>relpages</structname> and
30217 <structname>reltuples</structname> of the table
30218 <structname>mytable</structname>:
30219 <programlisting>
30220 SELECT pg_restore_relation_stats(
30221 'relation', 'mytable'::regclass,
30222 'relpages', 173::integer,
30223 'reltuples', 10000::float4);
30224 </programlisting>
30225 </para>
30226 <para>
30227 Minor errors are reported as a <literal>WARNING</literal> and
30228 ignored, and remaining statistics will still be restored. If all
30229 specified statistics are successfully restored, return
30230 <literal>true</literal>, otherwise <literal>false</literal>.
30231 </para>
30232 </entry>
30233 </row>
30235 <row>
30236 <entry role="func_table_entry">
30237 <para role="func_signature">
30238 <indexterm>
30239 <primary>pg_set_attribute_stats</primary>
30240 </indexterm>
30241 <function>pg_set_attribute_stats</function> (
30242 <parameter>relation</parameter> <type>regclass</type>,
30243 <parameter>attname</parameter> <type>name</type>,
30244 <parameter>inherited</parameter> <type>boolean</type>
30245 <optional>, <parameter>null_frac</parameter> <type>real</type></optional>
30246 <optional>, <parameter>avg_width</parameter> <type>integer</type></optional>
30247 <optional>, <parameter>n_distinct</parameter> <type>real</type></optional>
30248 <optional>, <parameter>most_common_vals</parameter> <type>text</type>, <parameter>most_common_freqs</parameter> <type>real[]</type> </optional>
30249 <optional>, <parameter>histogram_bounds</parameter> <type>text</type> </optional>
30250 <optional>, <parameter>correlation</parameter> <type>real</type> </optional>
30251 <optional>, <parameter>most_common_elems</parameter> <type>text</type>, <parameter>most_common_elem_freqs</parameter> <type>real[]</type> </optional>
30252 <optional>, <parameter>elem_count_histogram</parameter> <type>real[]</type> </optional>
30253 <optional>, <parameter>range_length_histogram</parameter> <type>text</type> </optional>
30254 <optional>, <parameter>range_empty_frac</parameter> <type>real</type> </optional>
30255 <optional>, <parameter>range_bounds_histogram</parameter> <type>text</type> </optional> )
30256 <returnvalue>void</returnvalue>
30257 </para>
30258 <para>
30259 Creates or updates attribute-level statistics for the given relation
30260 and attribute name to the specified values. The parameters correspond
30261 to attributes of the same name found in the <link
30262 linkend="view-pg-stats"><structname>pg_stats</structname></link>
30263 view.
30264 </para>
30265 <para>
30266 Optional parameters default to <literal>NULL</literal>, which leave
30267 the corresponding statistic unchanged.
30268 </para>
30269 <para>
30270 Ordinarily, these statistics are collected automatically or updated
30271 as a part of <xref linkend="sql-vacuum"/> or <xref
30272 linkend="sql-analyze"/>, so it's not necessary to call this
30273 function. However, it may be useful when testing the effects of
30274 statistics on the planner to understand or anticipate plan changes.
30275 </para>
30276 <para>
30277 The caller must have the <literal>MAINTAIN</literal> privilege on
30278 the table or be the owner of the database.
30279 </para>
30280 </entry>
30281 </row>
30283 <row>
30284 <entry role="func_table_entry">
30285 <para role="func_signature">
30286 <indexterm>
30287 <primary>pg_clear_attribute_stats</primary>
30288 </indexterm>
30289 <function>pg_clear_attribute_stats</function> (
30290 <parameter>relation</parameter> <type>regclass</type>,
30291 <parameter>attname</parameter> <type>name</type>,
30292 <parameter>inherited</parameter> <type>boolean</type> )
30293 <returnvalue>void</returnvalue>
30294 </para>
30295 <para>
30296 Clears table-level statistics for the given relation attribute, as
30297 though the table was newly created.
30298 </para>
30299 <para>
30300 The caller must have the <literal>MAINTAIN</literal> privilege on
30301 the table or be the owner of the database.
30302 </para>
30303 </entry>
30304 </row>
30306 <row>
30307 <entry role="func_table_entry"><para role="func_signature">
30308 <indexterm>
30309 <primary>pg_restore_attribute_stats</primary>
30310 </indexterm>
30311 <function>pg_restore_attribute_stats</function> (
30312 <literal>VARIADIC</literal> <parameter>kwargs</parameter> <type>"any"</type> )
30313 <returnvalue>boolean</returnvalue>
30314 </para>
30315 <para>
30316 Similar to <function>pg_set_attribute_stats()</function>, but
30317 intended for bulk restore of attribute statistics. The tracked
30318 statistics may change from version to version, so the primary purpose
30319 of this function is to maintain a consistent function signature to
30320 avoid errors when restoring statistics from previous versions.
30321 </para>
30322 <para>
30323 Arguments are passed as pairs of <replaceable>argname</replaceable>
30324 and <replaceable>argvalue</replaceable>, where
30325 <replaceable>argname</replaceable> corresponds to a named argument in
30326 <function>pg_set_attribute_stats()</function> and
30327 <replaceable>argvalue</replaceable> is of the corresponding type.
30328 </para>
30329 <para>
30330 Additionally, this function supports argument name
30331 <literal>version</literal> of type <type>integer</type>, which
30332 specifies the version from which the statistics originated, improving
30333 interpretation of older statistics.
30334 </para>
30335 <para>
30336 For example, to set the <structname>avg_width</structname> and
30337 <structname>null_frac</structname> for the attribute
30338 <structname>col1</structname> of the table
30339 <structname>mytable</structname>:
30340 <programlisting>
30341 SELECT pg_restore_attribute_stats(
30342 'relation', 'mytable'::regclass,
30343 'attname', 'col1'::name,
30344 'inherited', false,
30345 'avg_width', 125::integer,
30346 'null_frac', 0.5::real);
30347 </programlisting>
30348 </para>
30349 <para>
30350 Minor errors are reported as a <literal>WARNING</literal> and
30351 ignored, and remaining statistics will still be restored. If all
30352 specified statistics are successfully restored, return
30353 <literal>true</literal>, otherwise <literal>false</literal>.
30354 </para>
30355 </entry>
30356 </row>
30357 </tbody>
30358 </tgroup>
30359 </table>
30361 <para>
30362 <xref linkend="functions-info-partition"/> lists functions that provide
30363 information about the structure of partitioned tables.
30364 </para>
30366 <table id="functions-info-partition">
30367 <title>Partitioning Information Functions</title>
30368 <tgroup cols="1">
30369 <thead>
30370 <row>
30371 <entry role="func_table_entry"><para role="func_signature">
30372 Function
30373 </para>
30374 <para>
30375 Description
30376 </para></entry>
30377 </row>
30378 </thead>
30380 <tbody>
30381 <row>
30382 <entry role="func_table_entry"><para role="func_signature">
30383 <indexterm>
30384 <primary>pg_partition_tree</primary>
30385 </indexterm>
30386 <function>pg_partition_tree</function> ( <type>regclass</type> )
30387 <returnvalue>setof record</returnvalue>
30388 ( <parameter>relid</parameter> <type>regclass</type>,
30389 <parameter>parentrelid</parameter> <type>regclass</type>,
30390 <parameter>isleaf</parameter> <type>boolean</type>,
30391 <parameter>level</parameter> <type>integer</type> )
30392 </para>
30393 <para>
30394 Lists the tables or indexes in the partition tree of the
30395 given partitioned table or partitioned index, with one row for each
30396 partition. Information provided includes the OID of the partition,
30397 the OID of its immediate parent, a boolean value telling if the
30398 partition is a leaf, and an integer telling its level in the hierarchy.
30399 The level value is 0 for the input table or index, 1 for its
30400 immediate child partitions, 2 for their partitions, and so on.
30401 Returns no rows if the relation does not exist or is not a partition
30402 or partitioned table.
30403 </para></entry>
30404 </row>
30406 <row>
30407 <entry role="func_table_entry"><para role="func_signature">
30408 <indexterm>
30409 <primary>pg_partition_ancestors</primary>
30410 </indexterm>
30411 <function>pg_partition_ancestors</function> ( <type>regclass</type> )
30412 <returnvalue>setof regclass</returnvalue>
30413 </para>
30414 <para>
30415 Lists the ancestor relations of the given partition,
30416 including the relation itself. Returns no rows if the relation
30417 does not exist or is not a partition or partitioned table.
30418 </para></entry>
30419 </row>
30421 <row>
30422 <entry role="func_table_entry"><para role="func_signature">
30423 <indexterm>
30424 <primary>pg_partition_root</primary>
30425 </indexterm>
30426 <function>pg_partition_root</function> ( <type>regclass</type> )
30427 <returnvalue>regclass</returnvalue>
30428 </para>
30429 <para>
30430 Returns the top-most parent of the partition tree to which the given
30431 relation belongs. Returns <literal>NULL</literal> if the relation
30432 does not exist or is not a partition or partitioned table.
30433 </para></entry>
30434 </row>
30435 </tbody>
30436 </tgroup>
30437 </table>
30439 <para>
30440 For example, to check the total size of the data contained in a
30441 partitioned table <structname>measurement</structname>, one could use the
30442 following query:
30443 <programlisting>
30444 SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
30445 FROM pg_partition_tree('measurement');
30446 </programlisting>
30447 </para>
30449 </sect2>
30451 <sect2 id="functions-admin-index">
30452 <title>Index Maintenance Functions</title>
30454 <para>
30455 <xref linkend="functions-admin-index-table"/> shows the functions
30456 available for index maintenance tasks. (Note that these maintenance
30457 tasks are normally done automatically by autovacuum; use of these
30458 functions is only required in special cases.)
30459 These functions cannot be executed during recovery.
30460 Use of these functions is restricted to superusers and the owner
30461 of the given index.
30462 </para>
30464 <table id="functions-admin-index-table">
30465 <title>Index Maintenance Functions</title>
30466 <tgroup cols="1">
30467 <thead>
30468 <row>
30469 <entry role="func_table_entry"><para role="func_signature">
30470 Function
30471 </para>
30472 <para>
30473 Description
30474 </para></entry>
30475 </row>
30476 </thead>
30478 <tbody>
30479 <row>
30480 <entry role="func_table_entry"><para role="func_signature">
30481 <indexterm>
30482 <primary>brin_summarize_new_values</primary>
30483 </indexterm>
30484 <function>brin_summarize_new_values</function> ( <parameter>index</parameter> <type>regclass</type> )
30485 <returnvalue>integer</returnvalue>
30486 </para>
30487 <para>
30488 Scans the specified BRIN index to find page ranges in the base table
30489 that are not currently summarized by the index; for any such range it
30490 creates a new summary index tuple by scanning those table pages.
30491 Returns the number of new page range summaries that were inserted
30492 into the index.
30493 </para></entry>
30494 </row>
30496 <row>
30497 <entry role="func_table_entry"><para role="func_signature">
30498 <indexterm>
30499 <primary>brin_summarize_range</primary>
30500 </indexterm>
30501 <function>brin_summarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
30502 <returnvalue>integer</returnvalue>
30503 </para>
30504 <para>
30505 Summarizes the page range covering the given block, if not already
30506 summarized. This is
30507 like <function>brin_summarize_new_values</function> except that it
30508 only processes the page range that covers the given table block number.
30509 </para></entry>
30510 </row>
30512 <row>
30513 <entry role="func_table_entry"><para role="func_signature">
30514 <indexterm>
30515 <primary>brin_desummarize_range</primary>
30516 </indexterm>
30517 <function>brin_desummarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
30518 <returnvalue>void</returnvalue>
30519 </para>
30520 <para>
30521 Removes the BRIN index tuple that summarizes the page range covering
30522 the given table block, if there is one.
30523 </para></entry>
30524 </row>
30526 <row>
30527 <entry role="func_table_entry"><para role="func_signature">
30528 <indexterm>
30529 <primary>gin_clean_pending_list</primary>
30530 </indexterm>
30531 <function>gin_clean_pending_list</function> ( <parameter>index</parameter> <type>regclass</type> )
30532 <returnvalue>bigint</returnvalue>
30533 </para>
30534 <para>
30535 Cleans up the <quote>pending</quote> list of the specified GIN index
30536 by moving entries in it, in bulk, to the main GIN data structure.
30537 Returns the number of pages removed from the pending list.
30538 If the argument is a GIN index built with
30539 the <literal>fastupdate</literal> option disabled, no cleanup happens
30540 and the result is zero, because the index doesn't have a pending list.
30541 See <xref linkend="gin-fast-update"/> and <xref linkend="gin-tips"/>
30542 for details about the pending list and <literal>fastupdate</literal>
30543 option.
30544 </para></entry>
30545 </row>
30546 </tbody>
30547 </tgroup>
30548 </table>
30550 </sect2>
30552 <sect2 id="functions-admin-genfile">
30553 <title>Generic File Access Functions</title>
30555 <para>
30556 The functions shown in <xref
30557 linkend="functions-admin-genfile-table"/> provide native access to
30558 files on the machine hosting the server. Only files within the
30559 database cluster directory and the <varname>log_directory</varname> can be
30560 accessed, unless the user is a superuser or is granted the role
30561 <literal>pg_read_server_files</literal>. Use a relative path for files in
30562 the cluster directory, and a path matching the <varname>log_directory</varname>
30563 configuration setting for log files.
30564 </para>
30566 <para>
30567 Note that granting users the EXECUTE privilege on
30568 <function>pg_read_file()</function>, or related functions, allows them the
30569 ability to read any file on the server that the database server process can
30570 read; these functions bypass all in-database privilege checks. This means
30571 that, for example, a user with such access is able to read the contents of
30572 the <structname>pg_authid</structname> table where authentication
30573 information is stored, as well as read any table data in the database.
30574 Therefore, granting access to these functions should be carefully
30575 considered.
30576 </para>
30578 <para>
30579 When granting privilege on these functions, note that the table entries
30580 showing optional parameters are mostly implemented as several physical
30581 functions with different parameter lists. Privilege must be granted
30582 separately on each such function, if it is to be
30583 used. <application>psql</application>'s <command>\df</command> command
30584 can be useful to check what the actual function signatures are.
30585 </para>
30587 <para>
30588 Some of these functions take an optional <parameter>missing_ok</parameter>
30589 parameter, which specifies the behavior when the file or directory does
30590 not exist. If <literal>true</literal>, the function
30591 returns <literal>NULL</literal> or an empty result set, as appropriate.
30592 If <literal>false</literal>, an error is raised. (Failure conditions
30593 other than <quote>file not found</quote> are reported as errors in any
30594 case.) The default is <literal>false</literal>.
30595 </para>
30597 <table id="functions-admin-genfile-table">
30598 <title>Generic File Access Functions</title>
30599 <tgroup cols="1">
30600 <thead>
30601 <row>
30602 <entry role="func_table_entry"><para role="func_signature">
30603 Function
30604 </para>
30605 <para>
30606 Description
30607 </para></entry>
30608 </row>
30609 </thead>
30611 <tbody>
30612 <row>
30613 <entry role="func_table_entry"><para role="func_signature">
30614 <indexterm>
30615 <primary>pg_ls_dir</primary>
30616 </indexterm>
30617 <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> )
30618 <returnvalue>setof text</returnvalue>
30619 </para>
30620 <para>
30621 Returns the names of all files (and directories and other special
30622 files) in the specified
30623 directory. The <parameter>include_dot_dirs</parameter> parameter
30624 indicates whether <quote>.</quote> and <quote>..</quote> are to be
30625 included in the result set; the default is to exclude them. Including
30626 them can be useful when <parameter>missing_ok</parameter>
30627 is <literal>true</literal>, to distinguish an empty directory from a
30628 non-existent directory.
30629 </para>
30630 <para>
30631 This function is restricted to superusers by default, but other users
30632 can be granted EXECUTE to run the function.
30633 </para></entry>
30634 </row>
30636 <row>
30637 <entry role="func_table_entry"><para role="func_signature">
30638 <indexterm>
30639 <primary>pg_ls_logdir</primary>
30640 </indexterm>
30641 <function>pg_ls_logdir</function> ()
30642 <returnvalue>setof record</returnvalue>
30643 ( <parameter>name</parameter> <type>text</type>,
30644 <parameter>size</parameter> <type>bigint</type>,
30645 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30646 </para>
30647 <para>
30648 Returns the name, size, and last modification time (mtime) of each
30649 ordinary file in the server's log directory. Filenames beginning with
30650 a dot, directories, and other special files are excluded.
30651 </para>
30652 <para>
30653 This function is restricted to superusers and roles with privileges of
30654 the <literal>pg_monitor</literal> role by default, but other users can
30655 be granted EXECUTE to run the function.
30656 </para></entry>
30657 </row>
30659 <row>
30660 <entry role="func_table_entry"><para role="func_signature">
30661 <indexterm>
30662 <primary>pg_ls_waldir</primary>
30663 </indexterm>
30664 <function>pg_ls_waldir</function> ()
30665 <returnvalue>setof record</returnvalue>
30666 ( <parameter>name</parameter> <type>text</type>,
30667 <parameter>size</parameter> <type>bigint</type>,
30668 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30669 </para>
30670 <para>
30671 Returns the name, size, and last modification time (mtime) of each
30672 ordinary file in the server's write-ahead log (WAL) directory.
30673 Filenames beginning with a dot, directories, and other special files
30674 are excluded.
30675 </para>
30676 <para>
30677 This function is restricted to superusers and roles with privileges of
30678 the <literal>pg_monitor</literal> role by default, but other users can
30679 be granted EXECUTE to run the function.
30680 </para></entry>
30681 </row>
30683 <row>
30684 <entry role="func_table_entry"><para role="func_signature">
30685 <indexterm>
30686 <primary>pg_ls_logicalmapdir</primary>
30687 </indexterm>
30688 <function>pg_ls_logicalmapdir</function> ()
30689 <returnvalue>setof record</returnvalue>
30690 ( <parameter>name</parameter> <type>text</type>,
30691 <parameter>size</parameter> <type>bigint</type>,
30692 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30693 </para>
30694 <para>
30695 Returns the name, size, and last modification time (mtime) of each
30696 ordinary file in the server's <filename>pg_logical/mappings</filename>
30697 directory. Filenames beginning with a dot, directories, and other
30698 special files are excluded.
30699 </para>
30700 <para>
30701 This function is restricted to superusers and members of
30702 the <literal>pg_monitor</literal> role by default, but other users can
30703 be granted EXECUTE to run the function.
30704 </para></entry>
30705 </row>
30707 <row>
30708 <entry role="func_table_entry"><para role="func_signature">
30709 <indexterm>
30710 <primary>pg_ls_logicalsnapdir</primary>
30711 </indexterm>
30712 <function>pg_ls_logicalsnapdir</function> ()
30713 <returnvalue>setof record</returnvalue>
30714 ( <parameter>name</parameter> <type>text</type>,
30715 <parameter>size</parameter> <type>bigint</type>,
30716 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30717 </para>
30718 <para>
30719 Returns the name, size, and last modification time (mtime) of each
30720 ordinary file in the server's <filename>pg_logical/snapshots</filename>
30721 directory. Filenames beginning with a dot, directories, and other
30722 special files are excluded.
30723 </para>
30724 <para>
30725 This function is restricted to superusers and members of
30726 the <literal>pg_monitor</literal> role by default, but other users can
30727 be granted EXECUTE to run the function.
30728 </para></entry>
30729 </row>
30731 <row>
30732 <entry role="func_table_entry"><para role="func_signature">
30733 <indexterm>
30734 <primary>pg_ls_replslotdir</primary>
30735 </indexterm>
30736 <function>pg_ls_replslotdir</function> ( <parameter>slot_name</parameter> <type>text</type> )
30737 <returnvalue>setof record</returnvalue>
30738 ( <parameter>name</parameter> <type>text</type>,
30739 <parameter>size</parameter> <type>bigint</type>,
30740 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30741 </para>
30742 <para>
30743 Returns the name, size, and last modification time (mtime) of each
30744 ordinary file in the server's <filename>pg_replslot/slot_name</filename>
30745 directory, where <parameter>slot_name</parameter> is the name of the
30746 replication slot provided as input of the function. Filenames beginning
30747 with a dot, directories, and other special files are excluded.
30748 </para>
30749 <para>
30750 This function is restricted to superusers and members of
30751 the <literal>pg_monitor</literal> role by default, but other users can
30752 be granted EXECUTE to run the function.
30753 </para></entry>
30754 </row>
30756 <row>
30757 <entry role="func_table_entry"><para role="func_signature">
30758 <indexterm>
30759 <primary>pg_ls_summariesdir</primary>
30760 </indexterm>
30761 <function>pg_ls_summariesdir</function> ()
30762 <returnvalue>setof record</returnvalue>
30763 ( <parameter>name</parameter> <type>text</type>,
30764 <parameter>size</parameter> <type>bigint</type>,
30765 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30766 </para>
30767 <para>
30768 Returns the name, size, and last modification time (mtime) of each
30769 ordinary file in the server's WAL summaries directory
30770 (<filename>pg_wal/summaries</filename>). Filenames beginning
30771 with a dot, directories, and other special files are excluded.
30772 </para>
30773 <para>
30774 This function is restricted to superusers and members of
30775 the <literal>pg_monitor</literal> role by default, but other users can
30776 be granted EXECUTE to run the function.
30777 </para></entry>
30778 </row>
30780 <row>
30781 <entry role="func_table_entry"><para role="func_signature">
30782 <indexterm>
30783 <primary>pg_ls_archive_statusdir</primary>
30784 </indexterm>
30785 <function>pg_ls_archive_statusdir</function> ()
30786 <returnvalue>setof record</returnvalue>
30787 ( <parameter>name</parameter> <type>text</type>,
30788 <parameter>size</parameter> <type>bigint</type>,
30789 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30790 </para>
30791 <para>
30792 Returns the name, size, and last modification time (mtime) of each
30793 ordinary file in the server's WAL archive status directory
30794 (<filename>pg_wal/archive_status</filename>). Filenames beginning
30795 with a dot, directories, and other special files are excluded.
30796 </para>
30797 <para>
30798 This function is restricted to superusers and members of
30799 the <literal>pg_monitor</literal> role by default, but other users can
30800 be granted EXECUTE to run the function.
30801 </para></entry>
30802 </row>
30804 <row>
30805 <entry role="func_table_entry"><para role="func_signature">
30807 <indexterm>
30808 <primary>pg_ls_tmpdir</primary>
30809 </indexterm>
30810 <function>pg_ls_tmpdir</function> ( <optional> <parameter>tablespace</parameter> <type>oid</type> </optional> )
30811 <returnvalue>setof record</returnvalue>
30812 ( <parameter>name</parameter> <type>text</type>,
30813 <parameter>size</parameter> <type>bigint</type>,
30814 <parameter>modification</parameter> <type>timestamp with time zone</type> )
30815 </para>
30816 <para>
30817 Returns the name, size, and last modification time (mtime) of each
30818 ordinary file in the temporary file directory for the
30819 specified <parameter>tablespace</parameter>.
30820 If <parameter>tablespace</parameter> is not provided,
30821 the <literal>pg_default</literal> tablespace is examined. Filenames
30822 beginning with a dot, directories, and other special files are
30823 excluded.
30824 </para>
30825 <para>
30826 This function is restricted to superusers and members of
30827 the <literal>pg_monitor</literal> role by default, but other users can
30828 be granted EXECUTE to run the function.
30829 </para></entry>
30830 </row>
30832 <row>
30833 <entry role="func_table_entry"><para role="func_signature">
30834 <indexterm>
30835 <primary>pg_read_file</primary>
30836 </indexterm>
30837 <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> )
30838 <returnvalue>text</returnvalue>
30839 </para>
30840 <para>
30841 Returns all or part of a text file, starting at the
30842 given byte <parameter>offset</parameter>, returning at
30843 most <parameter>length</parameter> bytes (less if the end of file is
30844 reached first). If <parameter>offset</parameter> is negative, it is
30845 relative to the end of the file. If <parameter>offset</parameter>
30846 and <parameter>length</parameter> are omitted, the entire file is
30847 returned. The bytes read from the file are interpreted as a string in
30848 the database's encoding; an error is thrown if they are not valid in
30849 that encoding.
30850 </para>
30851 <para>
30852 This function is restricted to superusers by default, but other users
30853 can be granted EXECUTE to run the function.
30854 </para></entry>
30855 </row>
30857 <row>
30858 <entry role="func_table_entry"><para role="func_signature">
30859 <indexterm>
30860 <primary>pg_read_binary_file</primary>
30861 </indexterm>
30862 <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> )
30863 <returnvalue>bytea</returnvalue>
30864 </para>
30865 <para>
30866 Returns all or part of a file. This function is identical to
30867 <function>pg_read_file</function> except that it can read arbitrary
30868 binary data, returning the result as <type>bytea</type>
30869 not <type>text</type>; accordingly, no encoding checks are performed.
30870 </para>
30871 <para>
30872 This function is restricted to superusers by default, but other users
30873 can be granted EXECUTE to run the function.
30874 </para>
30875 <para>
30876 In combination with the <function>convert_from</function> function,
30877 this function can be used to read a text file in a specified encoding
30878 and convert to the database's encoding:
30879 <programlisting>
30880 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
30881 </programlisting>
30882 </para></entry>
30883 </row>
30885 <row>
30886 <entry role="func_table_entry"><para role="func_signature">
30887 <indexterm>
30888 <primary>pg_stat_file</primary>
30889 </indexterm>
30890 <function>pg_stat_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
30891 <returnvalue>record</returnvalue>
30892 ( <parameter>size</parameter> <type>bigint</type>,
30893 <parameter>access</parameter> <type>timestamp with time zone</type>,
30894 <parameter>modification</parameter> <type>timestamp with time zone</type>,
30895 <parameter>change</parameter> <type>timestamp with time zone</type>,
30896 <parameter>creation</parameter> <type>timestamp with time zone</type>,
30897 <parameter>isdir</parameter> <type>boolean</type> )
30898 </para>
30899 <para>
30900 Returns a record containing the file's size, last access time stamp,
30901 last modification time stamp, last file status change time stamp (Unix
30902 platforms only), file creation time stamp (Windows only), and a flag
30903 indicating if it is a directory.
30904 </para>
30905 <para>
30906 This function is restricted to superusers by default, but other users
30907 can be granted EXECUTE to run the function.
30908 </para></entry>
30909 </row>
30911 </tbody>
30912 </tgroup>
30913 </table>
30915 </sect2>
30917 <sect2 id="functions-advisory-locks">
30918 <title>Advisory Lock Functions</title>
30920 <para>
30921 The functions shown in <xref linkend="functions-advisory-locks-table"/>
30922 manage advisory locks. For details about proper use of these functions,
30923 see <xref linkend="advisory-locks"/>.
30924 </para>
30926 <para>
30927 All these functions are intended to be used to lock application-defined
30928 resources, which can be identified either by a single 64-bit key value or
30929 two 32-bit key values (note that these two key spaces do not overlap).
30930 If another session already holds a conflicting lock on the same resource
30931 identifier, the functions will either wait until the resource becomes
30932 available, or return a <literal>false</literal> result, as appropriate for
30933 the function.
30934 Locks can be either shared or exclusive: a shared lock does not conflict
30935 with other shared locks on the same resource, only with exclusive locks.
30936 Locks can be taken at session level (so that they are held until released
30937 or the session ends) or at transaction level (so that they are held until
30938 the current transaction ends; there is no provision for manual release).
30939 Multiple session-level lock requests stack, so that if the same resource
30940 identifier is locked three times there must then be three unlock requests
30941 to release the resource in advance of session end.
30942 </para>
30944 <table id="functions-advisory-locks-table">
30945 <title>Advisory Lock Functions</title>
30946 <tgroup cols="1">
30947 <thead>
30948 <row>
30949 <entry role="func_table_entry"><para role="func_signature">
30950 Function
30951 </para>
30952 <para>
30953 Description
30954 </para></entry>
30955 </row>
30956 </thead>
30958 <tbody>
30959 <row>
30960 <entry role="func_table_entry"><para role="func_signature">
30961 <indexterm>
30962 <primary>pg_advisory_lock</primary>
30963 </indexterm>
30964 <function>pg_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
30965 <returnvalue>void</returnvalue>
30966 </para>
30967 <para role="func_signature">
30968 <function>pg_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
30969 <returnvalue>void</returnvalue>
30970 </para>
30971 <para>
30972 Obtains an exclusive session-level advisory lock, waiting if necessary.
30973 </para></entry>
30974 </row>
30976 <row>
30977 <entry role="func_table_entry"><para role="func_signature">
30978 <indexterm>
30979 <primary>pg_advisory_lock_shared</primary>
30980 </indexterm>
30981 <function>pg_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
30982 <returnvalue>void</returnvalue>
30983 </para>
30984 <para role="func_signature">
30985 <function>pg_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
30986 <returnvalue>void</returnvalue>
30987 </para>
30988 <para>
30989 Obtains a shared session-level advisory lock, waiting if necessary.
30990 </para></entry>
30991 </row>
30993 <row>
30994 <entry role="func_table_entry"><para role="func_signature">
30995 <indexterm>
30996 <primary>pg_advisory_unlock</primary>
30997 </indexterm>
30998 <function>pg_advisory_unlock</function> ( <parameter>key</parameter> <type>bigint</type> )
30999 <returnvalue>boolean</returnvalue>
31000 </para>
31001 <para role="func_signature">
31002 <function>pg_advisory_unlock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31003 <returnvalue>boolean</returnvalue>
31004 </para>
31005 <para>
31006 Releases a previously-acquired exclusive session-level advisory lock.
31007 Returns <literal>true</literal> if the lock is successfully released.
31008 If the lock was not held, <literal>false</literal> is returned, and in
31009 addition, an SQL warning will be reported by the server.
31010 </para></entry>
31011 </row>
31013 <row>
31014 <entry role="func_table_entry"><para role="func_signature">
31015 <indexterm>
31016 <primary>pg_advisory_unlock_all</primary>
31017 </indexterm>
31018 <function>pg_advisory_unlock_all</function> ()
31019 <returnvalue>void</returnvalue>
31020 </para>
31021 <para>
31022 Releases all session-level advisory locks held by the current session.
31023 (This function is implicitly invoked at session end, even if the
31024 client disconnects ungracefully.)
31025 </para></entry>
31026 </row>
31028 <row>
31029 <entry role="func_table_entry"><para role="func_signature">
31030 <indexterm>
31031 <primary>pg_advisory_unlock_shared</primary>
31032 </indexterm>
31033 <function>pg_advisory_unlock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
31034 <returnvalue>boolean</returnvalue>
31035 </para>
31036 <para role="func_signature">
31037 <function>pg_advisory_unlock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31038 <returnvalue>boolean</returnvalue>
31039 </para>
31040 <para>
31041 Releases a previously-acquired shared session-level advisory lock.
31042 Returns <literal>true</literal> if the lock is successfully released.
31043 If the lock was not held, <literal>false</literal> is returned, and in
31044 addition, an SQL warning will be reported by the server.
31045 </para></entry>
31046 </row>
31048 <row>
31049 <entry role="func_table_entry"><para role="func_signature">
31050 <indexterm>
31051 <primary>pg_advisory_xact_lock</primary>
31052 </indexterm>
31053 <function>pg_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
31054 <returnvalue>void</returnvalue>
31055 </para>
31056 <para role="func_signature">
31057 <function>pg_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31058 <returnvalue>void</returnvalue>
31059 </para>
31060 <para>
31061 Obtains an exclusive transaction-level advisory lock, waiting if
31062 necessary.
31063 </para></entry>
31064 </row>
31066 <row>
31067 <entry role="func_table_entry"><para role="func_signature">
31068 <indexterm>
31069 <primary>pg_advisory_xact_lock_shared</primary>
31070 </indexterm>
31071 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
31072 <returnvalue>void</returnvalue>
31073 </para>
31074 <para role="func_signature">
31075 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31076 <returnvalue>void</returnvalue>
31077 </para>
31078 <para>
31079 Obtains a shared transaction-level advisory lock, waiting if
31080 necessary.
31081 </para></entry>
31082 </row>
31084 <row>
31085 <entry role="func_table_entry"><para role="func_signature">
31086 <indexterm>
31087 <primary>pg_try_advisory_lock</primary>
31088 </indexterm>
31089 <function>pg_try_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
31090 <returnvalue>boolean</returnvalue>
31091 </para>
31092 <para role="func_signature">
31093 <function>pg_try_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31094 <returnvalue>boolean</returnvalue>
31095 </para>
31096 <para>
31097 Obtains an exclusive session-level advisory lock if available.
31098 This will either obtain the lock immediately and
31099 return <literal>true</literal>, or return <literal>false</literal>
31100 without waiting if the lock cannot be acquired immediately.
31101 </para></entry>
31102 </row>
31104 <row>
31105 <entry role="func_table_entry"><para role="func_signature">
31106 <indexterm>
31107 <primary>pg_try_advisory_lock_shared</primary>
31108 </indexterm>
31109 <function>pg_try_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
31110 <returnvalue>boolean</returnvalue>
31111 </para>
31112 <para role="func_signature">
31113 <function>pg_try_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31114 <returnvalue>boolean</returnvalue>
31115 </para>
31116 <para>
31117 Obtains a shared session-level advisory lock if available.
31118 This will either obtain the lock immediately and
31119 return <literal>true</literal>, or return <literal>false</literal>
31120 without waiting if the lock cannot be acquired immediately.
31121 </para></entry>
31122 </row>
31124 <row>
31125 <entry role="func_table_entry"><para role="func_signature">
31126 <indexterm>
31127 <primary>pg_try_advisory_xact_lock</primary>
31128 </indexterm>
31129 <function>pg_try_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
31130 <returnvalue>boolean</returnvalue>
31131 </para>
31132 <para role="func_signature">
31133 <function>pg_try_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31134 <returnvalue>boolean</returnvalue>
31135 </para>
31136 <para>
31137 Obtains an exclusive transaction-level advisory lock if available.
31138 This will either obtain the lock immediately and
31139 return <literal>true</literal>, or return <literal>false</literal>
31140 without waiting if the lock cannot be acquired immediately.
31141 </para></entry>
31142 </row>
31144 <row>
31145 <entry role="func_table_entry"><para role="func_signature">
31146 <indexterm>
31147 <primary>pg_try_advisory_xact_lock_shared</primary>
31148 </indexterm>
31149 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
31150 <returnvalue>boolean</returnvalue>
31151 </para>
31152 <para role="func_signature">
31153 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
31154 <returnvalue>boolean</returnvalue>
31155 </para>
31156 <para>
31157 Obtains a shared transaction-level advisory lock if available.
31158 This will either obtain the lock immediately and
31159 return <literal>true</literal>, or return <literal>false</literal>
31160 without waiting if the lock cannot be acquired immediately.
31161 </para></entry>
31162 </row>
31163 </tbody>
31164 </tgroup>
31165 </table>
31167 </sect2>
31169 </sect1>
31171 <sect1 id="functions-trigger">
31172 <title>Trigger Functions</title>
31174 <para>
31175 While many uses of triggers involve user-written trigger functions,
31176 <productname>PostgreSQL</productname> provides a few built-in trigger
31177 functions that can be used directly in user-defined triggers. These
31178 are summarized in <xref linkend="builtin-triggers-table"/>.
31179 (Additional built-in trigger functions exist, which implement foreign
31180 key constraints and deferred index constraints. Those are not documented
31181 here since users need not use them directly.)
31182 </para>
31184 <para>
31185 For more information about creating triggers, see
31186 <xref linkend="sql-createtrigger"/>.
31187 </para>
31189 <table id="builtin-triggers-table">
31190 <title>Built-In Trigger Functions</title>
31191 <tgroup cols="1">
31192 <thead>
31193 <row>
31194 <entry role="func_table_entry"><para role="func_signature">
31195 Function
31196 </para>
31197 <para>
31198 Description
31199 </para>
31200 <para>
31201 Example Usage
31202 </para></entry>
31203 </row>
31204 </thead>
31206 <tbody>
31207 <row>
31208 <entry role="func_table_entry"><para role="func_signature">
31209 <indexterm>
31210 <primary>suppress_redundant_updates_trigger</primary>
31211 </indexterm>
31212 <function>suppress_redundant_updates_trigger</function> ( )
31213 <returnvalue>trigger</returnvalue>
31214 </para>
31215 <para>
31216 Suppresses do-nothing update operations. See below for details.
31217 </para>
31218 <para>
31219 <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()</literal>
31220 </para></entry>
31221 </row>
31223 <row>
31224 <entry role="func_table_entry"><para role="func_signature">
31225 <indexterm>
31226 <primary>tsvector_update_trigger</primary>
31227 </indexterm>
31228 <function>tsvector_update_trigger</function> ( )
31229 <returnvalue>trigger</returnvalue>
31230 </para>
31231 <para>
31232 Automatically updates a <type>tsvector</type> column from associated
31233 plain-text document column(s). The text search configuration to use
31234 is specified by name as a trigger argument. See
31235 <xref linkend="textsearch-update-triggers"/> for details.
31236 </para>
31237 <para>
31238 <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal>
31239 </para></entry>
31240 </row>
31242 <row>
31243 <entry role="func_table_entry"><para role="func_signature">
31244 <indexterm>
31245 <primary>tsvector_update_trigger_column</primary>
31246 </indexterm>
31247 <function>tsvector_update_trigger_column</function> ( )
31248 <returnvalue>trigger</returnvalue>
31249 </para>
31250 <para>
31251 Automatically updates a <type>tsvector</type> column from associated
31252 plain-text document column(s). The text search configuration to use
31253 is taken from a <type>regconfig</type> column of the table. See
31254 <xref linkend="textsearch-update-triggers"/> for details.
31255 </para>
31256 <para>
31257 <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)</literal>
31258 </para></entry>
31259 </row>
31260 </tbody>
31261 </tgroup>
31262 </table>
31264 <para>
31265 The <function>suppress_redundant_updates_trigger</function> function,
31266 when applied as a row-level <literal>BEFORE UPDATE</literal> trigger,
31267 will prevent any update that does not actually change the data in the
31268 row from taking place. This overrides the normal behavior which always
31269 performs a physical row update
31270 regardless of whether or not the data has changed. (This normal behavior
31271 makes updates run faster, since no checking is required, and is also
31272 useful in certain cases.)
31273 </para>
31275 <para>
31276 Ideally, you should avoid running updates that don't actually
31277 change the data in the record. Redundant updates can cost considerable
31278 unnecessary time, especially if there are lots of indexes to alter,
31279 and space in dead rows that will eventually have to be vacuumed.
31280 However, detecting such situations in client code is not
31281 always easy, or even possible, and writing expressions to detect
31282 them can be error-prone. An alternative is to use
31283 <function>suppress_redundant_updates_trigger</function>, which will skip
31284 updates that don't change the data. You should use this with care,
31285 however. The trigger takes a small but non-trivial time for each record,
31286 so if most of the records affected by updates do actually change,
31287 use of this trigger will make updates run slower on average.
31288 </para>
31290 <para>
31291 The <function>suppress_redundant_updates_trigger</function> function can be
31292 added to a table like this:
31293 <programlisting>
31294 CREATE TRIGGER z_min_update
31295 BEFORE UPDATE ON tablename
31296 FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger();
31297 </programlisting>
31298 In most cases, you need to fire this trigger last for each row, so that
31299 it does not override other triggers that might wish to alter the row.
31300 Bearing in mind that triggers fire in name order, you would therefore
31301 choose a trigger name that comes after the name of any other trigger
31302 you might have on the table. (Hence the <quote>z</quote> prefix in the
31303 example.)
31304 </para>
31305 </sect1>
31307 <sect1 id="functions-event-triggers">
31308 <title>Event Trigger Functions</title>
31310 <para>
31311 <productname>PostgreSQL</productname> provides these helper functions
31312 to retrieve information from event triggers.
31313 </para>
31315 <para>
31316 For more information about event triggers,
31317 see <xref linkend="event-triggers"/>.
31318 </para>
31320 <sect2 id="pg-event-trigger-ddl-command-end-functions">
31321 <title>Capturing Changes at Command End</title>
31323 <indexterm>
31324 <primary>pg_event_trigger_ddl_commands</primary>
31325 </indexterm>
31327 <synopsis>
31328 <function>pg_event_trigger_ddl_commands</function> () <returnvalue>setof record</returnvalue>
31329 </synopsis>
31331 <para>
31332 <function>pg_event_trigger_ddl_commands</function> returns a list of
31333 <acronym>DDL</acronym> commands executed by each user action,
31334 when invoked in a function attached to a
31335 <literal>ddl_command_end</literal> event trigger. If called in any other
31336 context, an error is raised.
31337 <function>pg_event_trigger_ddl_commands</function> returns one row for each
31338 base command executed; some commands that are a single SQL sentence
31339 may return more than one row. This function returns the following
31340 columns:
31342 <informaltable>
31343 <tgroup cols="3">
31344 <thead>
31345 <row>
31346 <entry>Name</entry>
31347 <entry>Type</entry>
31348 <entry>Description</entry>
31349 </row>
31350 </thead>
31352 <tbody>
31353 <row>
31354 <entry><literal>classid</literal></entry>
31355 <entry><type>oid</type></entry>
31356 <entry>OID of catalog the object belongs in</entry>
31357 </row>
31358 <row>
31359 <entry><literal>objid</literal></entry>
31360 <entry><type>oid</type></entry>
31361 <entry>OID of the object itself</entry>
31362 </row>
31363 <row>
31364 <entry><literal>objsubid</literal></entry>
31365 <entry><type>integer</type></entry>
31366 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
31367 </row>
31368 <row>
31369 <entry><literal>command_tag</literal></entry>
31370 <entry><type>text</type></entry>
31371 <entry>Command tag</entry>
31372 </row>
31373 <row>
31374 <entry><literal>object_type</literal></entry>
31375 <entry><type>text</type></entry>
31376 <entry>Type of the object</entry>
31377 </row>
31378 <row>
31379 <entry><literal>schema_name</literal></entry>
31380 <entry><type>text</type></entry>
31381 <entry>
31382 Name of the schema the object belongs in, if any; otherwise <literal>NULL</literal>.
31383 No quoting is applied.
31384 </entry>
31385 </row>
31386 <row>
31387 <entry><literal>object_identity</literal></entry>
31388 <entry><type>text</type></entry>
31389 <entry>
31390 Text rendering of the object identity, schema-qualified. Each
31391 identifier included in the identity is quoted if necessary.
31392 </entry>
31393 </row>
31394 <row>
31395 <entry><literal>in_extension</literal></entry>
31396 <entry><type>boolean</type></entry>
31397 <entry>True if the command is part of an extension script</entry>
31398 </row>
31399 <row>
31400 <entry><literal>command</literal></entry>
31401 <entry><type>pg_ddl_command</type></entry>
31402 <entry>
31403 A complete representation of the command, in internal format.
31404 This cannot be output directly, but it can be passed to other
31405 functions to obtain different pieces of information about the
31406 command.
31407 </entry>
31408 </row>
31409 </tbody>
31410 </tgroup>
31411 </informaltable>
31412 </para>
31413 </sect2>
31415 <sect2 id="pg-event-trigger-sql-drop-functions">
31416 <title>Processing Objects Dropped by a DDL Command</title>
31418 <indexterm>
31419 <primary>pg_event_trigger_dropped_objects</primary>
31420 </indexterm>
31422 <synopsis>
31423 <function>pg_event_trigger_dropped_objects</function> () <returnvalue>setof record</returnvalue>
31424 </synopsis>
31426 <para>
31427 <function>pg_event_trigger_dropped_objects</function> returns a list of all objects
31428 dropped by the command in whose <literal>sql_drop</literal> event it is called.
31429 If called in any other context, an error is raised.
31430 This function returns the following columns:
31432 <informaltable>
31433 <tgroup cols="3">
31434 <thead>
31435 <row>
31436 <entry>Name</entry>
31437 <entry>Type</entry>
31438 <entry>Description</entry>
31439 </row>
31440 </thead>
31442 <tbody>
31443 <row>
31444 <entry><literal>classid</literal></entry>
31445 <entry><type>oid</type></entry>
31446 <entry>OID of catalog the object belonged in</entry>
31447 </row>
31448 <row>
31449 <entry><literal>objid</literal></entry>
31450 <entry><type>oid</type></entry>
31451 <entry>OID of the object itself</entry>
31452 </row>
31453 <row>
31454 <entry><literal>objsubid</literal></entry>
31455 <entry><type>integer</type></entry>
31456 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
31457 </row>
31458 <row>
31459 <entry><literal>original</literal></entry>
31460 <entry><type>boolean</type></entry>
31461 <entry>True if this was one of the root object(s) of the deletion</entry>
31462 </row>
31463 <row>
31464 <entry><literal>normal</literal></entry>
31465 <entry><type>boolean</type></entry>
31466 <entry>
31467 True if there was a normal dependency relationship
31468 in the dependency graph leading to this object
31469 </entry>
31470 </row>
31471 <row>
31472 <entry><literal>is_temporary</literal></entry>
31473 <entry><type>boolean</type></entry>
31474 <entry>
31475 True if this was a temporary object
31476 </entry>
31477 </row>
31478 <row>
31479 <entry><literal>object_type</literal></entry>
31480 <entry><type>text</type></entry>
31481 <entry>Type of the object</entry>
31482 </row>
31483 <row>
31484 <entry><literal>schema_name</literal></entry>
31485 <entry><type>text</type></entry>
31486 <entry>
31487 Name of the schema the object belonged in, if any; otherwise <literal>NULL</literal>.
31488 No quoting is applied.
31489 </entry>
31490 </row>
31491 <row>
31492 <entry><literal>object_name</literal></entry>
31493 <entry><type>text</type></entry>
31494 <entry>
31495 Name of the object, if the combination of schema and name can be
31496 used as a unique identifier for the object; otherwise <literal>NULL</literal>.
31497 No quoting is applied, and name is never schema-qualified.
31498 </entry>
31499 </row>
31500 <row>
31501 <entry><literal>object_identity</literal></entry>
31502 <entry><type>text</type></entry>
31503 <entry>
31504 Text rendering of the object identity, schema-qualified. Each
31505 identifier included in the identity is quoted if necessary.
31506 </entry>
31507 </row>
31508 <row>
31509 <entry><literal>address_names</literal></entry>
31510 <entry><type>text[]</type></entry>
31511 <entry>
31512 An array that, together with <literal>object_type</literal> and
31513 <literal>address_args</literal>, can be used by
31514 the <function>pg_get_object_address</function> function to
31515 recreate the object address in a remote server containing an
31516 identically named object of the same kind.
31517 </entry>
31518 </row>
31519 <row>
31520 <entry><literal>address_args</literal></entry>
31521 <entry><type>text[]</type></entry>
31522 <entry>
31523 Complement for <literal>address_names</literal>
31524 </entry>
31525 </row>
31526 </tbody>
31527 </tgroup>
31528 </informaltable>
31529 </para>
31531 <para>
31532 The <function>pg_event_trigger_dropped_objects</function> function can be used
31533 in an event trigger like this:
31534 <programlisting>
31535 CREATE FUNCTION test_event_trigger_for_drops()
31536 RETURNS event_trigger LANGUAGE plpgsql AS $$
31537 DECLARE
31538 obj record;
31539 BEGIN
31540 FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
31541 LOOP
31542 RAISE NOTICE '% dropped object: % %.% %',
31543 tg_tag,
31544 obj.object_type,
31545 obj.schema_name,
31546 obj.object_name,
31547 obj.object_identity;
31548 END LOOP;
31549 END;
31551 CREATE EVENT TRIGGER test_event_trigger_for_drops
31552 ON sql_drop
31553 EXECUTE FUNCTION test_event_trigger_for_drops();
31554 </programlisting>
31555 </para>
31556 </sect2>
31558 <sect2 id="pg-event-trigger-table-rewrite-functions">
31559 <title>Handling a Table Rewrite Event</title>
31561 <para>
31562 The functions shown in
31563 <xref linkend="functions-event-trigger-table-rewrite"/>
31564 provide information about a table for which a
31565 <literal>table_rewrite</literal> event has just been called.
31566 If called in any other context, an error is raised.
31567 </para>
31569 <table id="functions-event-trigger-table-rewrite">
31570 <title>Table Rewrite Information Functions</title>
31571 <tgroup cols="1">
31572 <thead>
31573 <row>
31574 <entry role="func_table_entry"><para role="func_signature">
31575 Function
31576 </para>
31577 <para>
31578 Description
31579 </para></entry>
31580 </row>
31581 </thead>
31583 <tbody>
31584 <row>
31585 <entry role="func_table_entry"><para role="func_signature">
31586 <indexterm>
31587 <primary>pg_event_trigger_table_rewrite_oid</primary>
31588 </indexterm>
31589 <function>pg_event_trigger_table_rewrite_oid</function> ()
31590 <returnvalue>oid</returnvalue>
31591 </para>
31592 <para>
31593 Returns the OID of the table about to be rewritten.
31594 </para></entry>
31595 </row>
31597 <row>
31598 <entry role="func_table_entry"><para role="func_signature">
31599 <indexterm>
31600 <primary>pg_event_trigger_table_rewrite_reason</primary>
31601 </indexterm>
31602 <function>pg_event_trigger_table_rewrite_reason</function> ()
31603 <returnvalue>integer</returnvalue>
31604 </para>
31605 <para>
31606 Returns a code explaining the reason(s) for rewriting. The value is
31607 a bitmap built from the following values: <literal>1</literal>
31608 (the table has changed its persistence), <literal>2</literal>
31609 (default value of a column has changed), <literal>4</literal>
31610 (a column has a new data type) and <literal>8</literal>
31611 (the table access method has changed).
31612 </para></entry>
31613 </row>
31614 </tbody>
31615 </tgroup>
31616 </table>
31618 <para>
31619 These functions can be used in an event trigger like this:
31620 <programlisting>
31621 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
31622 RETURNS event_trigger
31623 LANGUAGE plpgsql AS
31625 BEGIN
31626 RAISE NOTICE 'rewriting table % for reason %',
31627 pg_event_trigger_table_rewrite_oid()::regclass,
31628 pg_event_trigger_table_rewrite_reason();
31629 END;
31632 CREATE EVENT TRIGGER test_table_rewrite_oid
31633 ON table_rewrite
31634 EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
31635 </programlisting>
31636 </para>
31637 </sect2>
31638 </sect1>
31640 <sect1 id="functions-statistics">
31641 <title>Statistics Information Functions</title>
31643 <indexterm zone="functions-statistics">
31644 <primary>function</primary>
31645 <secondary>statistics</secondary>
31646 </indexterm>
31648 <para>
31649 <productname>PostgreSQL</productname> provides a function to inspect complex
31650 statistics defined using the <command>CREATE STATISTICS</command> command.
31651 </para>
31653 <sect2 id="functions-statistics-mcv">
31654 <title>Inspecting MCV Lists</title>
31656 <indexterm>
31657 <primary>pg_mcv_list_items</primary>
31658 </indexterm>
31660 <synopsis>
31661 <function>pg_mcv_list_items</function> ( <type>pg_mcv_list</type> ) <returnvalue>setof record</returnvalue>
31662 </synopsis>
31664 <para>
31665 <function>pg_mcv_list_items</function> returns a set of records describing
31666 all items stored in a multi-column <acronym>MCV</acronym> list. It
31667 returns the following columns:
31669 <informaltable>
31670 <tgroup cols="3">
31671 <thead>
31672 <row>
31673 <entry>Name</entry>
31674 <entry>Type</entry>
31675 <entry>Description</entry>
31676 </row>
31677 </thead>
31679 <tbody>
31680 <row>
31681 <entry><literal>index</literal></entry>
31682 <entry><type>integer</type></entry>
31683 <entry>index of the item in the <acronym>MCV</acronym> list</entry>
31684 </row>
31685 <row>
31686 <entry><literal>values</literal></entry>
31687 <entry><type>text[]</type></entry>
31688 <entry>values stored in the MCV item</entry>
31689 </row>
31690 <row>
31691 <entry><literal>nulls</literal></entry>
31692 <entry><type>boolean[]</type></entry>
31693 <entry>flags identifying <literal>NULL</literal> values</entry>
31694 </row>
31695 <row>
31696 <entry><literal>frequency</literal></entry>
31697 <entry><type>double precision</type></entry>
31698 <entry>frequency of this <acronym>MCV</acronym> item</entry>
31699 </row>
31700 <row>
31701 <entry><literal>base_frequency</literal></entry>
31702 <entry><type>double precision</type></entry>
31703 <entry>base frequency of this <acronym>MCV</acronym> item</entry>
31704 </row>
31705 </tbody>
31706 </tgroup>
31707 </informaltable>
31708 </para>
31710 <para>
31711 The <function>pg_mcv_list_items</function> function can be used like this:
31713 <programlisting>
31714 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
31715 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
31716 </programlisting>
31718 Values of the <type>pg_mcv_list</type> type can be obtained only from the
31719 <structname>pg_statistic_ext_data</structname>.<structfield>stxdmcv</structfield>
31720 column.
31721 </para>
31722 </sect2>
31724 </sect1>
31726 </chapter>