doc: Consistently spell case-insensitive
[pgsql.git] / doc / src / sgml / func.sgml
blob8dd63c04556106db982eaf33a416a6bc2ddf301a
1 <!-- doc/src/sgml/func.sgml -->
3 <chapter id="functions">
4 <title>Functions and Operators</title>
6 <indexterm zone="functions">
7 <primary>function</primary>
8 </indexterm>
10 <indexterm zone="functions">
11 <primary>operator</primary>
12 </indexterm>
14 <para>
15 <productname>PostgreSQL</productname> provides a large number of
16 functions and operators for the built-in data types. This chapter
17 describes most of them, although additional special-purpose functions
18 appear in relevant sections of the manual. Users can also
19 define their own functions and operators, as described in
20 <xref linkend="server-programming"/>. The
21 <application>psql</application> commands <command>\df</command> and
22 <command>\do</command> can be used to list all
23 available functions and operators, respectively.
24 </para>
26 <para>
27 The notation used throughout this chapter to describe the argument and
28 result data types of a function or operator is like this:
29 <synopsis>
30 <function>repeat</function> ( <type>text</type>, <type>integer</type> ) <returnvalue>text</returnvalue>
31 </synopsis>
32 which says that the function <function>repeat</function> takes one text and
33 one integer argument and returns a result of type text. The right arrow
34 is also used to indicate the result of an example, thus:
35 <programlisting>
36 repeat('Pg', 4) <returnvalue>PgPgPgPg</returnvalue>
37 </programlisting>
38 </para>
40 <para>
41 If you are concerned about portability then note that most of
42 the functions and operators described in this chapter, with the
43 exception of the most trivial arithmetic and comparison operators
44 and some explicitly marked functions, are not specified by the
45 <acronym>SQL</acronym> standard. Some of this extended functionality
46 is present in other <acronym>SQL</acronym> database management
47 systems, and in many cases this functionality is compatible and
48 consistent between the various implementations.
49 </para>
52 <sect1 id="functions-logical">
53 <title>Logical Operators</title>
55 <indexterm zone="functions-logical">
56 <primary>operator</primary>
57 <secondary>logical</secondary>
58 </indexterm>
60 <indexterm>
61 <primary>Boolean</primary>
62 <secondary>operators</secondary>
63 <see>operators, logical</see>
64 </indexterm>
66 <para>
67 The usual logical operators are available:
69 <indexterm>
70 <primary>AND (operator)</primary>
71 </indexterm>
73 <indexterm>
74 <primary>OR (operator)</primary>
75 </indexterm>
77 <indexterm>
78 <primary>NOT (operator)</primary>
79 </indexterm>
81 <indexterm>
82 <primary>conjunction</primary>
83 </indexterm>
85 <indexterm>
86 <primary>disjunction</primary>
87 </indexterm>
89 <indexterm>
90 <primary>negation</primary>
91 </indexterm>
93 <synopsis>
94 <type>boolean</type> <literal>AND</literal> <type>boolean</type> <returnvalue>boolean</returnvalue>
95 <type>boolean</type> <literal>OR</literal> <type>boolean</type> <returnvalue>boolean</returnvalue>
96 <literal>NOT</literal> <type>boolean</type> <returnvalue>boolean</returnvalue>
97 </synopsis>
99 <acronym>SQL</acronym> uses a three-valued logic system with true,
100 false, and <literal>null</literal>, which represents <quote>unknown</quote>.
101 Observe the following truth tables:
103 <informaltable>
104 <tgroup cols="4">
105 <thead>
106 <row>
107 <entry><replaceable>a</replaceable></entry>
108 <entry><replaceable>b</replaceable></entry>
109 <entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
110 <entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
111 </row>
112 </thead>
114 <tbody>
115 <row>
116 <entry>TRUE</entry>
117 <entry>TRUE</entry>
118 <entry>TRUE</entry>
119 <entry>TRUE</entry>
120 </row>
122 <row>
123 <entry>TRUE</entry>
124 <entry>FALSE</entry>
125 <entry>FALSE</entry>
126 <entry>TRUE</entry>
127 </row>
129 <row>
130 <entry>TRUE</entry>
131 <entry>NULL</entry>
132 <entry>NULL</entry>
133 <entry>TRUE</entry>
134 </row>
136 <row>
137 <entry>FALSE</entry>
138 <entry>FALSE</entry>
139 <entry>FALSE</entry>
140 <entry>FALSE</entry>
141 </row>
143 <row>
144 <entry>FALSE</entry>
145 <entry>NULL</entry>
146 <entry>FALSE</entry>
147 <entry>NULL</entry>
148 </row>
150 <row>
151 <entry>NULL</entry>
152 <entry>NULL</entry>
153 <entry>NULL</entry>
154 <entry>NULL</entry>
155 </row>
156 </tbody>
157 </tgroup>
158 </informaltable>
160 <informaltable>
161 <tgroup cols="2">
162 <thead>
163 <row>
164 <entry><replaceable>a</replaceable></entry>
165 <entry>NOT <replaceable>a</replaceable></entry>
166 </row>
167 </thead>
169 <tbody>
170 <row>
171 <entry>TRUE</entry>
172 <entry>FALSE</entry>
173 </row>
175 <row>
176 <entry>FALSE</entry>
177 <entry>TRUE</entry>
178 </row>
180 <row>
181 <entry>NULL</entry>
182 <entry>NULL</entry>
183 </row>
184 </tbody>
185 </tgroup>
186 </informaltable>
187 </para>
189 <para>
190 The operators <literal>AND</literal> and <literal>OR</literal> are
191 commutative, that is, you can switch the left and right operands
192 without affecting the result. (However, it is not guaranteed that
193 the left operand is evaluated before the right operand. See <xref
194 linkend="syntax-express-eval"/> for more information about the
195 order of evaluation of subexpressions.)
196 </para>
197 </sect1>
199 <sect1 id="functions-comparison">
200 <title>Comparison Functions and Operators</title>
202 <indexterm zone="functions-comparison">
203 <primary>comparison</primary>
204 <secondary>operators</secondary>
205 </indexterm>
207 <para>
208 The usual comparison operators are available, as shown in <xref
209 linkend="functions-comparison-op-table"/>.
210 </para>
212 <table id="functions-comparison-op-table">
213 <title>Comparison Operators</title>
214 <tgroup cols="2">
215 <thead>
216 <row>
217 <entry>Operator</entry>
218 <entry>Description</entry>
219 </row>
220 </thead>
222 <tbody>
223 <row>
224 <entry>
225 <replaceable>datatype</replaceable> <literal>&lt;</literal> <replaceable>datatype</replaceable>
226 <returnvalue>boolean</returnvalue>
227 </entry>
228 <entry>Less than</entry>
229 </row>
231 <row>
232 <entry>
233 <replaceable>datatype</replaceable> <literal>&gt;</literal> <replaceable>datatype</replaceable>
234 <returnvalue>boolean</returnvalue>
235 </entry>
236 <entry>Greater than</entry>
237 </row>
239 <row>
240 <entry>
241 <replaceable>datatype</replaceable> <literal>&lt;=</literal> <replaceable>datatype</replaceable>
242 <returnvalue>boolean</returnvalue>
243 </entry>
244 <entry>Less than or equal to</entry>
245 </row>
247 <row>
248 <entry>
249 <replaceable>datatype</replaceable> <literal>&gt;=</literal> <replaceable>datatype</replaceable>
250 <returnvalue>boolean</returnvalue>
251 </entry>
252 <entry>Greater than or equal to</entry>
253 </row>
255 <row>
256 <entry>
257 <replaceable>datatype</replaceable> <literal>=</literal> <replaceable>datatype</replaceable>
258 <returnvalue>boolean</returnvalue>
259 </entry>
260 <entry>Equal</entry>
261 </row>
263 <row>
264 <entry>
265 <replaceable>datatype</replaceable> <literal>&lt;&gt;</literal> <replaceable>datatype</replaceable>
266 <returnvalue>boolean</returnvalue>
267 </entry>
268 <entry>Not equal</entry>
269 </row>
271 <row>
272 <entry>
273 <replaceable>datatype</replaceable> <literal>!=</literal> <replaceable>datatype</replaceable>
274 <returnvalue>boolean</returnvalue>
275 </entry>
276 <entry>Not equal</entry>
277 </row>
278 </tbody>
279 </tgroup>
280 </table>
282 <note>
283 <para>
284 <literal>&lt;&gt;</literal> is the standard SQL notation for <quote>not
285 equal</quote>. <literal>!=</literal> is an alias, which is converted
286 to <literal>&lt;&gt;</literal> at a very early stage of parsing.
287 Hence, it is not possible to implement <literal>!=</literal>
288 and <literal>&lt;&gt;</literal> operators that do different things.
289 </para>
290 </note>
292 <para>
293 These comparison operators are available for all built-in data types
294 that have a natural ordering, including numeric, string, and date/time
295 types. In addition, arrays, composite types, and ranges can be compared
296 if their component data types are comparable.
297 </para>
299 <para>
300 It is usually possible to compare values of related data
301 types as well; for example <type>integer</type> <literal>&gt;</literal>
302 <type>bigint</type> will work. Some cases of this sort are implemented
303 directly by <quote>cross-type</quote> comparison operators, but if no
304 such operator is available, the parser will coerce the less-general type
305 to the more-general type and apply the latter's comparison operator.
306 </para>
308 <para>
309 As shown above, all comparison operators are binary operators that
310 return values of type <type>boolean</type>. Thus, expressions like
311 <literal>1 &lt; 2 &lt; 3</literal> are not valid (because there is
312 no <literal>&lt;</literal> operator to compare a Boolean value with
313 <literal>3</literal>). Use the <literal>BETWEEN</literal> predicates
314 shown below to perform range tests.
315 </para>
317 <para>
318 There are also some comparison predicates, as shown in <xref
319 linkend="functions-comparison-pred-table"/>. These behave much like
320 operators, but have special syntax mandated by the SQL standard.
321 </para>
323 <table id="functions-comparison-pred-table">
324 <title>Comparison Predicates</title>
325 <tgroup cols="1">
326 <thead>
327 <row>
328 <entry role="func_table_entry"><para role="func_signature">
329 Predicate
330 </para>
331 <para>
332 Description
333 </para>
334 <para>
335 Example(s)
336 </para></entry>
337 </row>
338 </thead>
340 <tbody>
341 <row>
342 <entry role="func_table_entry"><para role="func_signature">
343 <replaceable>datatype</replaceable> <literal>BETWEEN</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
344 <returnvalue>boolean</returnvalue>
345 </para>
346 <para>
347 Between (inclusive of the range endpoints).
348 </para>
349 <para>
350 <literal>2 BETWEEN 1 AND 3</literal>
351 <returnvalue>t</returnvalue>
352 </para>
353 <para>
354 <literal>2 BETWEEN 3 AND 1</literal>
355 <returnvalue>f</returnvalue>
356 </para></entry>
357 </row>
359 <row>
360 <entry role="func_table_entry"><para role="func_signature">
361 <replaceable>datatype</replaceable> <literal>NOT BETWEEN</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
362 <returnvalue>boolean</returnvalue>
363 </para>
364 <para>
365 Not between (the negation of <literal>BETWEEN</literal>).
366 </para>
367 <para>
368 <literal>2 NOT BETWEEN 1 AND 3</literal>
369 <returnvalue>f</returnvalue>
370 </para></entry>
371 </row>
373 <row>
374 <entry role="func_table_entry"><para role="func_signature">
375 <replaceable>datatype</replaceable> <literal>BETWEEN SYMMETRIC</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
376 <returnvalue>boolean</returnvalue>
377 </para>
378 <para>
379 Between, after sorting the two endpoint values.
380 </para>
381 <para>
382 <literal>2 BETWEEN SYMMETRIC 3 AND 1</literal>
383 <returnvalue>t</returnvalue>
384 </para></entry>
385 </row>
387 <row>
388 <entry role="func_table_entry"><para role="func_signature">
389 <replaceable>datatype</replaceable> <literal>NOT BETWEEN SYMMETRIC</literal> <replaceable>datatype</replaceable> <literal>AND</literal> <replaceable>datatype</replaceable>
390 <returnvalue>boolean</returnvalue>
391 </para>
392 <para>
393 Not between, after sorting the two endpoint values.
394 </para>
395 <para>
396 <literal>2 NOT BETWEEN SYMMETRIC 3 AND 1</literal>
397 <returnvalue>f</returnvalue>
398 </para></entry>
399 </row>
401 <row>
402 <entry role="func_table_entry"><para role="func_signature">
403 <replaceable>datatype</replaceable> <literal>IS DISTINCT FROM</literal> <replaceable>datatype</replaceable>
404 <returnvalue>boolean</returnvalue>
405 </para>
406 <para>
407 Not equal, treating null as a comparable value.
408 </para>
409 <para>
410 <literal>1 IS DISTINCT FROM NULL</literal>
411 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
412 </para>
413 <para>
414 <literal>NULL IS DISTINCT FROM NULL</literal>
415 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
416 </para></entry>
417 </row>
419 <row>
420 <entry role="func_table_entry"><para role="func_signature">
421 <replaceable>datatype</replaceable> <literal>IS NOT DISTINCT FROM</literal> <replaceable>datatype</replaceable>
422 <returnvalue>boolean</returnvalue>
423 </para>
424 <para>
425 Equal, treating null as a comparable value.
426 </para>
427 <para>
428 <literal>1 IS NOT DISTINCT FROM NULL</literal>
429 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
430 </para>
431 <para>
432 <literal>NULL IS NOT DISTINCT FROM NULL</literal>
433 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
434 </para></entry>
435 </row>
437 <row>
438 <entry role="func_table_entry"><para role="func_signature">
439 <replaceable>datatype</replaceable> <literal>IS NULL</literal>
440 <returnvalue>boolean</returnvalue>
441 </para>
442 <para>
443 Test whether value is null.
444 </para>
445 <para>
446 <literal>1.5 IS NULL</literal>
447 <returnvalue>f</returnvalue>
448 </para></entry>
449 </row>
451 <row>
452 <entry role="func_table_entry"><para role="func_signature">
453 <replaceable>datatype</replaceable> <literal>IS NOT NULL</literal>
454 <returnvalue>boolean</returnvalue>
455 </para>
456 <para>
457 Test whether value is not null.
458 </para>
459 <para>
460 <literal>'null' IS NOT NULL</literal>
461 <returnvalue>t</returnvalue>
462 </para></entry>
463 </row>
465 <row>
466 <entry role="func_table_entry"><para role="func_signature">
467 <replaceable>datatype</replaceable> <literal>ISNULL</literal>
468 <returnvalue>boolean</returnvalue>
469 </para>
470 <para>
471 Test whether value is null (nonstandard syntax).
472 </para></entry>
473 </row>
475 <row>
476 <entry role="func_table_entry"><para role="func_signature">
477 <replaceable>datatype</replaceable> <literal>NOTNULL</literal>
478 <returnvalue>boolean</returnvalue>
479 </para>
480 <para>
481 Test whether value is not null (nonstandard syntax).
482 </para></entry>
483 </row>
485 <row>
486 <entry role="func_table_entry"><para role="func_signature">
487 <type>boolean</type> <literal>IS TRUE</literal>
488 <returnvalue>boolean</returnvalue>
489 </para>
490 <para>
491 Test whether boolean expression yields true.
492 </para>
493 <para>
494 <literal>true IS TRUE</literal>
495 <returnvalue>t</returnvalue>
496 </para>
497 <para>
498 <literal>NULL::boolean IS TRUE</literal>
499 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
500 </para></entry>
501 </row>
503 <row>
504 <entry role="func_table_entry"><para role="func_signature">
505 <type>boolean</type> <literal>IS NOT TRUE</literal>
506 <returnvalue>boolean</returnvalue>
507 </para>
508 <para>
509 Test whether boolean expression yields false or unknown.
510 </para>
511 <para>
512 <literal>true IS NOT TRUE</literal>
513 <returnvalue>f</returnvalue>
514 </para>
515 <para>
516 <literal>NULL::boolean IS NOT TRUE</literal>
517 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
518 </para></entry>
519 </row>
521 <row>
522 <entry role="func_table_entry"><para role="func_signature">
523 <type>boolean</type> <literal>IS FALSE</literal>
524 <returnvalue>boolean</returnvalue>
525 </para>
526 <para>
527 Test whether boolean expression yields false.
528 </para>
529 <para>
530 <literal>true IS FALSE</literal>
531 <returnvalue>f</returnvalue>
532 </para>
533 <para>
534 <literal>NULL::boolean IS FALSE</literal>
535 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
536 </para></entry>
537 </row>
539 <row>
540 <entry role="func_table_entry"><para role="func_signature">
541 <type>boolean</type> <literal>IS NOT FALSE</literal>
542 <returnvalue>boolean</returnvalue>
543 </para>
544 <para>
545 Test whether boolean expression yields true or unknown.
546 </para>
547 <para>
548 <literal>true IS NOT FALSE</literal>
549 <returnvalue>t</returnvalue>
550 </para>
551 <para>
552 <literal>NULL::boolean IS NOT FALSE</literal>
553 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
554 </para></entry>
555 </row>
557 <row>
558 <entry role="func_table_entry"><para role="func_signature">
559 <type>boolean</type> <literal>IS UNKNOWN</literal>
560 <returnvalue>boolean</returnvalue>
561 </para>
562 <para>
563 Test whether boolean expression yields unknown.
564 </para>
565 <para>
566 <literal>true IS UNKNOWN</literal>
567 <returnvalue>f</returnvalue>
568 </para>
569 <para>
570 <literal>NULL::boolean IS UNKNOWN</literal>
571 <returnvalue>t</returnvalue> (rather than <literal>NULL</literal>)
572 </para></entry>
573 </row>
575 <row>
576 <entry role="func_table_entry"><para role="func_signature">
577 <type>boolean</type> <literal>IS NOT UNKNOWN</literal>
578 <returnvalue>boolean</returnvalue>
579 </para>
580 <para>
581 Test whether boolean expression yields true or false.
582 </para>
583 <para>
584 <literal>true IS NOT UNKNOWN</literal>
585 <returnvalue>t</returnvalue>
586 </para>
587 <para>
588 <literal>NULL::boolean IS NOT UNKNOWN</literal>
589 <returnvalue>f</returnvalue> (rather than <literal>NULL</literal>)
590 </para></entry>
591 </row>
592 </tbody>
593 </tgroup>
594 </table>
596 <para>
597 <indexterm>
598 <primary>BETWEEN</primary>
599 </indexterm>
600 <indexterm>
601 <primary>BETWEEN SYMMETRIC</primary>
602 </indexterm>
603 The <token>BETWEEN</token> predicate simplifies range tests:
604 <synopsis>
605 <replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
606 </synopsis>
607 is equivalent to
608 <synopsis>
609 <replaceable>a</replaceable> &gt;= <replaceable>x</replaceable> AND <replaceable>a</replaceable> &lt;= <replaceable>y</replaceable>
610 </synopsis>
611 Notice that <token>BETWEEN</token> treats the endpoint values as included
612 in the range.
613 <literal>BETWEEN SYMMETRIC</literal> is like <literal>BETWEEN</literal>
614 except there is no requirement that the argument to the left of
615 <literal>AND</literal> be less than or equal to the argument on the right.
616 If it is not, those two arguments are automatically swapped, so that
617 a nonempty range is always implied.
618 </para>
620 <para>
621 The various variants of <literal>BETWEEN</literal> are implemented in
622 terms of the ordinary comparison operators, and therefore will work for
623 any data type(s) that can be compared.
624 </para>
626 <note>
627 <para>
628 The use of <literal>AND</literal> in the <literal>BETWEEN</literal>
629 syntax creates an ambiguity with the use of <literal>AND</literal> as a
630 logical operator. To resolve this, only a limited set of expression
631 types are allowed as the second argument of a <literal>BETWEEN</literal>
632 clause. If you need to write a more complex sub-expression
633 in <literal>BETWEEN</literal>, write parentheses around the
634 sub-expression.
635 </para>
636 </note>
638 <para>
639 <indexterm>
640 <primary>IS DISTINCT FROM</primary>
641 </indexterm>
642 <indexterm>
643 <primary>IS NOT DISTINCT FROM</primary>
644 </indexterm>
645 Ordinary comparison operators yield null (signifying <quote>unknown</quote>),
646 not true or false, when either input is null. For example,
647 <literal>7 = NULL</literal> yields null, as does <literal>7 &lt;&gt; NULL</literal>. When
648 this behavior is not suitable, use the
649 <literal>IS <optional> NOT </optional> DISTINCT FROM</literal> predicates:
650 <synopsis>
651 <replaceable>a</replaceable> IS DISTINCT FROM <replaceable>b</replaceable>
652 <replaceable>a</replaceable> IS NOT DISTINCT FROM <replaceable>b</replaceable>
653 </synopsis>
654 For non-null inputs, <literal>IS DISTINCT FROM</literal> is
655 the same as the <literal>&lt;&gt;</literal> operator. However, if both
656 inputs are null it returns false, and if only one input is
657 null it returns true. Similarly, <literal>IS NOT DISTINCT
658 FROM</literal> is identical to <literal>=</literal> for non-null
659 inputs, but it returns true when both inputs are null, and false when only
660 one input is null. Thus, these predicates effectively act as though null
661 were a normal data value, rather than <quote>unknown</quote>.
662 </para>
664 <para>
665 <indexterm>
666 <primary>IS NULL</primary>
667 </indexterm>
668 <indexterm>
669 <primary>IS NOT NULL</primary>
670 </indexterm>
671 <indexterm>
672 <primary>ISNULL</primary>
673 </indexterm>
674 <indexterm>
675 <primary>NOTNULL</primary>
676 </indexterm>
677 To check whether a value is or is not null, use the predicates:
678 <synopsis>
679 <replaceable>expression</replaceable> IS NULL
680 <replaceable>expression</replaceable> IS NOT NULL
681 </synopsis>
682 or the equivalent, but nonstandard, predicates:
683 <synopsis>
684 <replaceable>expression</replaceable> ISNULL
685 <replaceable>expression</replaceable> NOTNULL
686 </synopsis>
687 <indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
688 </para>
690 <para>
691 Do <emphasis>not</emphasis> write
692 <literal><replaceable>expression</replaceable> = NULL</literal>
693 because <literal>NULL</literal> is not <quote>equal to</quote>
694 <literal>NULL</literal>. (The null value represents an unknown value,
695 and it is not known whether two unknown values are equal.)
696 </para>
698 <tip>
699 <para>
700 Some applications might expect that
701 <literal><replaceable>expression</replaceable> = NULL</literal>
702 returns true if <replaceable>expression</replaceable> evaluates to
703 the null value. It is highly recommended that these applications
704 be modified to comply with the SQL standard. However, if that
705 cannot be done the <xref linkend="guc-transform-null-equals"/>
706 configuration variable is available. If it is enabled,
707 <productname>PostgreSQL</productname> will convert <literal>x =
708 NULL</literal> clauses to <literal>x IS NULL</literal>.
709 </para>
710 </tip>
712 <para>
713 If the <replaceable>expression</replaceable> is row-valued, then
714 <literal>IS NULL</literal> is true when the row expression itself is null
715 or when all the row's fields are null, while
716 <literal>IS NOT NULL</literal> is true when the row expression itself is non-null
717 and all the row's fields are non-null. Because of this behavior,
718 <literal>IS NULL</literal> and <literal>IS NOT NULL</literal> do not always return
719 inverse results for row-valued expressions; in particular, a row-valued
720 expression that contains both null and non-null fields will return false
721 for both tests. In some cases, it may be preferable to
722 write <replaceable>row</replaceable> <literal>IS DISTINCT FROM NULL</literal>
723 or <replaceable>row</replaceable> <literal>IS NOT DISTINCT FROM NULL</literal>,
724 which will simply check whether the overall row value is null without any
725 additional tests on the row fields.
726 </para>
728 <para>
729 <indexterm>
730 <primary>IS TRUE</primary>
731 </indexterm>
732 <indexterm>
733 <primary>IS NOT TRUE</primary>
734 </indexterm>
735 <indexterm>
736 <primary>IS FALSE</primary>
737 </indexterm>
738 <indexterm>
739 <primary>IS NOT FALSE</primary>
740 </indexterm>
741 <indexterm>
742 <primary>IS UNKNOWN</primary>
743 </indexterm>
744 <indexterm>
745 <primary>IS NOT UNKNOWN</primary>
746 </indexterm>
747 Boolean values can also be tested using the predicates
748 <synopsis>
749 <replaceable>boolean_expression</replaceable> IS TRUE
750 <replaceable>boolean_expression</replaceable> IS NOT TRUE
751 <replaceable>boolean_expression</replaceable> IS FALSE
752 <replaceable>boolean_expression</replaceable> IS NOT FALSE
753 <replaceable>boolean_expression</replaceable> IS UNKNOWN
754 <replaceable>boolean_expression</replaceable> IS NOT UNKNOWN
755 </synopsis>
756 These will always return true or false, never a null value, even when the
757 operand is null.
758 A null input is treated as the logical value <quote>unknown</quote>.
759 Notice that <literal>IS UNKNOWN</literal> and <literal>IS NOT UNKNOWN</literal> are
760 effectively the same as <literal>IS NULL</literal> and
761 <literal>IS NOT NULL</literal>, respectively, except that the input
762 expression must be of Boolean type.
763 </para>
765 <para>
766 Some comparison-related functions are also available, as shown in <xref
767 linkend="functions-comparison-func-table"/>.
768 </para>
770 <table id="functions-comparison-func-table">
771 <title>Comparison Functions</title>
772 <tgroup cols="1">
773 <thead>
774 <row>
775 <entry role="func_table_entry"><para role="func_signature">
776 Function
777 </para>
778 <para>
779 Description
780 </para>
781 <para>
782 Example(s)
783 </para></entry>
784 </row>
785 </thead>
787 <tbody>
788 <row>
789 <entry role="func_table_entry"><para role="func_signature">
790 <indexterm>
791 <primary>num_nonnulls</primary>
792 </indexterm>
793 <function>num_nonnulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
794 <returnvalue>integer</returnvalue>
795 </para>
796 <para>
797 Returns the number of non-null arguments.
798 </para>
799 <para>
800 <literal>num_nonnulls(1, NULL, 2)</literal>
801 <returnvalue>2</returnvalue>
802 </para></entry>
803 </row>
804 <row>
805 <entry role="func_table_entry"><para role="func_signature">
806 <indexterm>
807 <primary>num_nulls</primary>
808 </indexterm>
809 <function>num_nulls</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
810 <returnvalue>integer</returnvalue>
811 </para>
812 <para>
813 Returns the number of null arguments.
814 </para>
815 <para>
816 <literal>num_nulls(1, NULL, 2)</literal>
817 <returnvalue>1</returnvalue>
818 </para></entry>
819 </row>
820 </tbody>
821 </tgroup>
822 </table>
824 </sect1>
826 <sect1 id="functions-math">
827 <title>Mathematical Functions and Operators</title>
829 <para>
830 Mathematical operators are provided for many
831 <productname>PostgreSQL</productname> types. For types without
832 standard mathematical conventions
833 (e.g., date/time types) we
834 describe the actual behavior in subsequent sections.
835 </para>
837 <para>
838 <xref linkend="functions-math-op-table"/> shows the mathematical
839 operators that are available for the standard numeric types.
840 Unless otherwise noted, operators shown as
841 accepting <replaceable>numeric_type</replaceable> are available for all
842 the types <type>smallint</type>, <type>integer</type>,
843 <type>bigint</type>, <type>numeric</type>, <type>real</type>,
844 and <type>double precision</type>.
845 Operators shown as accepting <replaceable>integral_type</replaceable>
846 are available for the types <type>smallint</type>, <type>integer</type>,
847 and <type>bigint</type>.
848 Except where noted, each form of an operator returns the same data type
849 as its argument(s). Calls involving multiple argument data types, such
850 as <type>integer</type> <literal>+</literal> <type>numeric</type>,
851 are resolved by using the type appearing later in these lists.
852 </para>
854 <table id="functions-math-op-table">
855 <title>Mathematical Operators</title>
857 <tgroup cols="1">
858 <thead>
859 <row>
860 <entry role="func_table_entry"><para role="func_signature">
861 Operator
862 </para>
863 <para>
864 Description
865 </para>
866 <para>
867 Example(s)
868 </para></entry>
869 </row>
870 </thead>
872 <tbody>
873 <row>
874 <entry role="func_table_entry"><para role="func_signature">
875 <replaceable>numeric_type</replaceable> <literal>+</literal> <replaceable>numeric_type</replaceable>
876 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
877 </para>
878 <para>
879 Addition
880 </para>
881 <para>
882 <literal>2 + 3</literal>
883 <returnvalue>5</returnvalue>
884 </para></entry>
885 </row>
887 <row>
888 <entry role="func_table_entry"><para role="func_signature">
889 <literal>+</literal> <replaceable>numeric_type</replaceable>
890 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
891 </para>
892 <para>
893 Unary plus (no operation)
894 </para>
895 <para>
896 <literal>+ 3.5</literal>
897 <returnvalue>3.5</returnvalue>
898 </para></entry>
899 </row>
901 <row>
902 <entry role="func_table_entry"><para role="func_signature">
903 <replaceable>numeric_type</replaceable> <literal>-</literal> <replaceable>numeric_type</replaceable>
904 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
905 </para>
906 <para>
907 Subtraction
908 </para>
909 <para>
910 <literal>2 - 3</literal>
911 <returnvalue>-1</returnvalue>
912 </para></entry>
913 </row>
915 <row>
916 <entry role="func_table_entry"><para role="func_signature">
917 <literal>-</literal> <replaceable>numeric_type</replaceable>
918 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
919 </para>
920 <para>
921 Negation
922 </para>
923 <para>
924 <literal>- (-4)</literal>
925 <returnvalue>4</returnvalue>
926 </para></entry>
927 </row>
929 <row>
930 <entry role="func_table_entry"><para role="func_signature">
931 <replaceable>numeric_type</replaceable> <literal>*</literal> <replaceable>numeric_type</replaceable>
932 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
933 </para>
934 <para>
935 Multiplication
936 </para>
937 <para>
938 <literal>2 * 3</literal>
939 <returnvalue>6</returnvalue>
940 </para></entry>
941 </row>
943 <row>
944 <entry role="func_table_entry"><para role="func_signature">
945 <replaceable>numeric_type</replaceable> <literal>/</literal> <replaceable>numeric_type</replaceable>
946 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
947 </para>
948 <para>
949 Division (for integral types, division truncates the result towards
950 zero)
951 </para>
952 <para>
953 <literal>5.0 / 2</literal>
954 <returnvalue>2.5000000000000000</returnvalue>
955 </para>
956 <para>
957 <literal>5 / 2</literal>
958 <returnvalue>2</returnvalue>
959 </para>
960 <para>
961 <literal>(-5) / 2</literal>
962 <returnvalue>-2</returnvalue>
963 </para></entry>
964 </row>
966 <row>
967 <entry role="func_table_entry"><para role="func_signature">
968 <replaceable>numeric_type</replaceable> <literal>%</literal> <replaceable>numeric_type</replaceable>
969 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
970 </para>
971 <para>
972 Modulo (remainder); available for <type>smallint</type>,
973 <type>integer</type>, <type>bigint</type>, and <type>numeric</type>
974 </para>
975 <para>
976 <literal>5 % 4</literal>
977 <returnvalue>1</returnvalue>
978 </para></entry>
979 </row>
981 <row>
982 <entry role="func_table_entry"><para role="func_signature">
983 <type>numeric</type> <literal>^</literal> <type>numeric</type>
984 <returnvalue>numeric</returnvalue>
985 </para>
986 <para role="func_signature">
987 <type>double precision</type> <literal>^</literal> <type>double precision</type>
988 <returnvalue>double precision</returnvalue>
989 </para>
990 <para>
991 Exponentiation
992 </para>
993 <para>
994 <literal>2 ^ 3</literal>
995 <returnvalue>8</returnvalue>
996 </para>
997 <para>
998 Unlike typical mathematical practice, multiple uses of
999 <literal>^</literal> will associate left to right by default:
1000 </para>
1001 <para>
1002 <literal>2 ^ 3 ^ 3</literal>
1003 <returnvalue>512</returnvalue>
1004 </para>
1005 <para>
1006 <literal>2 ^ (3 ^ 3)</literal>
1007 <returnvalue>134217728</returnvalue>
1008 </para></entry>
1009 </row>
1011 <row>
1012 <entry role="func_table_entry"><para role="func_signature">
1013 <literal>|/</literal> <type>double precision</type>
1014 <returnvalue>double precision</returnvalue>
1015 </para>
1016 <para>
1017 Square root
1018 </para>
1019 <para>
1020 <literal>|/ 25.0</literal>
1021 <returnvalue>5</returnvalue>
1022 </para></entry>
1023 </row>
1025 <row>
1026 <entry role="func_table_entry"><para role="func_signature">
1027 <literal>||/</literal> <type>double precision</type>
1028 <returnvalue>double precision</returnvalue>
1029 </para>
1030 <para>
1031 Cube root
1032 </para>
1033 <para>
1034 <literal>||/ 64.0</literal>
1035 <returnvalue>4</returnvalue>
1036 </para></entry>
1037 </row>
1039 <row>
1040 <entry role="func_table_entry"><para role="func_signature">
1041 <literal>@</literal> <replaceable>numeric_type</replaceable>
1042 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1043 </para>
1044 <para>
1045 Absolute value
1046 </para>
1047 <para>
1048 <literal>@ -5.0</literal>
1049 <returnvalue>5.0</returnvalue>
1050 </para></entry>
1051 </row>
1053 <row>
1054 <entry role="func_table_entry"><para role="func_signature">
1055 <replaceable>integral_type</replaceable> <literal>&amp;</literal> <replaceable>integral_type</replaceable>
1056 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1057 </para>
1058 <para>
1059 Bitwise AND
1060 </para>
1061 <para>
1062 <literal>91 &amp; 15</literal>
1063 <returnvalue>11</returnvalue>
1064 </para></entry>
1065 </row>
1067 <row>
1068 <entry role="func_table_entry"><para role="func_signature">
1069 <replaceable>integral_type</replaceable> <literal>|</literal> <replaceable>integral_type</replaceable>
1070 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1071 </para>
1072 <para>
1073 Bitwise OR
1074 </para>
1075 <para>
1076 <literal>32 | 3</literal>
1077 <returnvalue>35</returnvalue>
1078 </para></entry>
1079 </row>
1081 <row>
1082 <entry role="func_table_entry"><para role="func_signature">
1083 <replaceable>integral_type</replaceable> <literal>#</literal> <replaceable>integral_type</replaceable>
1084 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1085 </para>
1086 <para>
1087 Bitwise exclusive OR
1088 </para>
1089 <para>
1090 <literal>17 # 5</literal>
1091 <returnvalue>20</returnvalue>
1092 </para></entry>
1093 </row>
1095 <row>
1096 <entry role="func_table_entry"><para role="func_signature">
1097 <literal>~</literal> <replaceable>integral_type</replaceable>
1098 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1099 </para>
1100 <para>
1101 Bitwise NOT
1102 </para>
1103 <para>
1104 <literal>~1</literal>
1105 <returnvalue>-2</returnvalue>
1106 </para></entry>
1107 </row>
1109 <row>
1110 <entry role="func_table_entry"><para role="func_signature">
1111 <replaceable>integral_type</replaceable> <literal>&lt;&lt;</literal> <type>integer</type>
1112 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1113 </para>
1114 <para>
1115 Bitwise shift left
1116 </para>
1117 <para>
1118 <literal>1 &lt;&lt; 4</literal>
1119 <returnvalue>16</returnvalue>
1120 </para></entry>
1121 </row>
1123 <row>
1124 <entry role="func_table_entry"><para role="func_signature">
1125 <replaceable>integral_type</replaceable> <literal>&gt;&gt;</literal> <type>integer</type>
1126 <returnvalue><replaceable>integral_type</replaceable></returnvalue>
1127 </para>
1128 <para>
1129 Bitwise shift right
1130 </para>
1131 <para>
1132 <literal>8 &gt;&gt; 2</literal>
1133 <returnvalue>2</returnvalue>
1134 </para></entry>
1135 </row>
1137 </tbody>
1138 </tgroup>
1139 </table>
1141 <para>
1142 <xref linkend="functions-math-func-table"/> shows the available
1143 mathematical functions.
1144 Many of these functions are provided in multiple forms with different
1145 argument types.
1146 Except where noted, any given form of a function returns the same
1147 data type as its argument(s); cross-type cases are resolved in the
1148 same way as explained above for operators.
1149 The functions working with <type>double precision</type> data are mostly
1150 implemented on top of the host system's C library; accuracy and behavior in
1151 boundary cases can therefore vary depending on the host system.
1152 </para>
1154 <table id="functions-math-func-table">
1155 <title>Mathematical Functions</title>
1156 <tgroup cols="1">
1157 <thead>
1158 <row>
1159 <entry role="func_table_entry"><para role="func_signature">
1160 Function
1161 </para>
1162 <para>
1163 Description
1164 </para>
1165 <para>
1166 Example(s)
1167 </para></entry>
1168 </row>
1169 </thead>
1171 <tbody>
1172 <row>
1173 <entry role="func_table_entry"><para role="func_signature">
1174 <indexterm>
1175 <primary>abs</primary>
1176 </indexterm>
1177 <function>abs</function> ( <replaceable>numeric_type</replaceable> )
1178 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1179 </para>
1180 <para>
1181 Absolute value
1182 </para>
1183 <para>
1184 <literal>abs(-17.4)</literal>
1185 <returnvalue>17.4</returnvalue>
1186 </para></entry>
1187 </row>
1189 <row>
1190 <entry role="func_table_entry"><para role="func_signature">
1191 <indexterm>
1192 <primary>cbrt</primary>
1193 </indexterm>
1194 <function>cbrt</function> ( <type>double precision</type> )
1195 <returnvalue>double precision</returnvalue>
1196 </para>
1197 <para>
1198 Cube root
1199 </para>
1200 <para>
1201 <literal>cbrt(64.0)</literal>
1202 <returnvalue>4</returnvalue>
1203 </para></entry>
1204 </row>
1206 <row>
1207 <entry role="func_table_entry"><para role="func_signature">
1208 <indexterm>
1209 <primary>ceil</primary>
1210 </indexterm>
1211 <function>ceil</function> ( <type>numeric</type> )
1212 <returnvalue>numeric</returnvalue>
1213 </para>
1214 <para role="func_signature">
1215 <function>ceil</function> ( <type>double precision</type> )
1216 <returnvalue>double precision</returnvalue>
1217 </para>
1218 <para>
1219 Nearest integer greater than or equal to argument
1220 </para>
1221 <para>
1222 <literal>ceil(42.2)</literal>
1223 <returnvalue>43</returnvalue>
1224 </para>
1225 <para>
1226 <literal>ceil(-42.8)</literal>
1227 <returnvalue>-42</returnvalue>
1228 </para></entry>
1229 </row>
1231 <row>
1232 <entry role="func_table_entry"><para role="func_signature">
1233 <indexterm>
1234 <primary>ceiling</primary>
1235 </indexterm>
1236 <function>ceiling</function> ( <type>numeric</type> )
1237 <returnvalue>numeric</returnvalue>
1238 </para>
1239 <para role="func_signature">
1240 <function>ceiling</function> ( <type>double precision</type> )
1241 <returnvalue>double precision</returnvalue>
1242 </para>
1243 <para>
1244 Nearest integer greater than or equal to argument (same
1245 as <function>ceil</function>)
1246 </para>
1247 <para>
1248 <literal>ceiling(95.3)</literal>
1249 <returnvalue>96</returnvalue>
1250 </para></entry>
1251 </row>
1253 <row>
1254 <entry role="func_table_entry"><para role="func_signature">
1255 <indexterm>
1256 <primary>degrees</primary>
1257 </indexterm>
1258 <function>degrees</function> ( <type>double precision</type> )
1259 <returnvalue>double precision</returnvalue>
1260 </para>
1261 <para>
1262 Converts radians to degrees
1263 </para>
1264 <para>
1265 <literal>degrees(0.5)</literal>
1266 <returnvalue>28.64788975654116</returnvalue>
1267 </para></entry>
1268 </row>
1270 <row>
1271 <entry role="func_table_entry"><para role="func_signature">
1272 <indexterm>
1273 <primary>div</primary>
1274 </indexterm>
1275 <function>div</function> ( <parameter>y</parameter> <type>numeric</type>,
1276 <parameter>x</parameter> <type>numeric</type> )
1277 <returnvalue>numeric</returnvalue>
1278 </para>
1279 <para>
1280 Integer quotient of <parameter>y</parameter>/<parameter>x</parameter>
1281 (truncates towards zero)
1282 </para>
1283 <para>
1284 <literal>div(9, 4)</literal>
1285 <returnvalue>2</returnvalue>
1286 </para></entry>
1287 </row>
1289 <row>
1290 <entry role="func_table_entry"><para role="func_signature">
1291 <indexterm>
1292 <primary>exp</primary>
1293 </indexterm>
1294 <function>exp</function> ( <type>numeric</type> )
1295 <returnvalue>numeric</returnvalue>
1296 </para>
1297 <para role="func_signature">
1298 <function>exp</function> ( <type>double precision</type> )
1299 <returnvalue>double precision</returnvalue>
1300 </para>
1301 <para>
1302 Exponential (<literal>e</literal> raised to the given power)
1303 </para>
1304 <para>
1305 <literal>exp(1.0)</literal>
1306 <returnvalue>2.7182818284590452</returnvalue>
1307 </para></entry>
1308 </row>
1310 <row>
1311 <entry role="func_table_entry"><para role="func_signature">
1312 <indexterm id="function-factorial">
1313 <primary>factorial</primary>
1314 </indexterm>
1315 <function>factorial</function> ( <type>bigint</type> )
1316 <returnvalue>numeric</returnvalue>
1317 </para>
1318 <para>
1319 Factorial
1320 </para>
1321 <para>
1322 <literal>factorial(5)</literal>
1323 <returnvalue>120</returnvalue>
1324 </para></entry>
1325 </row>
1327 <row>
1328 <entry role="func_table_entry"><para role="func_signature">
1329 <indexterm>
1330 <primary>floor</primary>
1331 </indexterm>
1332 <function>floor</function> ( <type>numeric</type> )
1333 <returnvalue>numeric</returnvalue>
1334 </para>
1335 <para role="func_signature">
1336 <function>floor</function> ( <type>double precision</type> )
1337 <returnvalue>double precision</returnvalue>
1338 </para>
1339 <para>
1340 Nearest integer less than or equal to argument
1341 </para>
1342 <para>
1343 <literal>floor(42.8)</literal>
1344 <returnvalue>42</returnvalue>
1345 </para>
1346 <para>
1347 <literal>floor(-42.8)</literal>
1348 <returnvalue>-43</returnvalue>
1349 </para></entry>
1350 </row>
1352 <row>
1353 <entry role="func_table_entry"><para role="func_signature">
1354 <indexterm>
1355 <primary>gcd</primary>
1356 </indexterm>
1357 <function>gcd</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> )
1358 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1359 </para>
1360 <para>
1361 Greatest common divisor (the largest positive number that divides both
1362 inputs with no remainder); returns <literal>0</literal> if both inputs
1363 are zero; available for <type>integer</type>, <type>bigint</type>,
1364 and <type>numeric</type>
1365 </para>
1366 <para>
1367 <literal>gcd(1071, 462)</literal>
1368 <returnvalue>21</returnvalue>
1369 </para></entry>
1370 </row>
1372 <row>
1373 <entry role="func_table_entry"><para role="func_signature">
1374 <indexterm>
1375 <primary>lcm</primary>
1376 </indexterm>
1377 <function>lcm</function> ( <replaceable>numeric_type</replaceable>, <replaceable>numeric_type</replaceable> )
1378 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1379 </para>
1380 <para>
1381 Least common multiple (the smallest strictly positive number that is
1382 an integral multiple of both inputs); returns <literal>0</literal> if
1383 either input is zero; available for <type>integer</type>,
1384 <type>bigint</type>, and <type>numeric</type>
1385 </para>
1386 <para>
1387 <literal>lcm(1071, 462)</literal>
1388 <returnvalue>23562</returnvalue>
1389 </para></entry>
1390 </row>
1392 <row>
1393 <entry role="func_table_entry"><para role="func_signature">
1394 <indexterm>
1395 <primary>ln</primary>
1396 </indexterm>
1397 <function>ln</function> ( <type>numeric</type> )
1398 <returnvalue>numeric</returnvalue>
1399 </para>
1400 <para role="func_signature">
1401 <function>ln</function> ( <type>double precision</type> )
1402 <returnvalue>double precision</returnvalue>
1403 </para>
1404 <para>
1405 Natural logarithm
1406 </para>
1407 <para>
1408 <literal>ln(2.0)</literal>
1409 <returnvalue>0.6931471805599453</returnvalue>
1410 </para></entry>
1411 </row>
1413 <row>
1414 <entry role="func_table_entry"><para role="func_signature">
1415 <indexterm>
1416 <primary>log</primary>
1417 </indexterm>
1418 <function>log</function> ( <type>numeric</type> )
1419 <returnvalue>numeric</returnvalue>
1420 </para>
1421 <para role="func_signature">
1422 <function>log</function> ( <type>double precision</type> )
1423 <returnvalue>double precision</returnvalue>
1424 </para>
1425 <para>
1426 Base 10 logarithm
1427 </para>
1428 <para>
1429 <literal>log(100)</literal>
1430 <returnvalue>2</returnvalue>
1431 </para></entry>
1432 </row>
1434 <row>
1435 <entry role="func_table_entry"><para role="func_signature">
1436 <indexterm>
1437 <primary>log10</primary>
1438 </indexterm>
1439 <function>log10</function> ( <type>numeric</type> )
1440 <returnvalue>numeric</returnvalue>
1441 </para>
1442 <para role="func_signature">
1443 <function>log10</function> ( <type>double precision</type> )
1444 <returnvalue>double precision</returnvalue>
1445 </para>
1446 <para>
1447 Base 10 logarithm (same as <function>log</function>)
1448 </para>
1449 <para>
1450 <literal>log10(1000)</literal>
1451 <returnvalue>3</returnvalue>
1452 </para></entry>
1453 </row>
1455 <row>
1456 <entry role="func_table_entry"><para role="func_signature">
1457 <function>log</function> ( <parameter>b</parameter> <type>numeric</type>,
1458 <parameter>x</parameter> <type>numeric</type> )
1459 <returnvalue>numeric</returnvalue>
1460 </para>
1461 <para>
1462 Logarithm of <parameter>x</parameter> to base <parameter>b</parameter>
1463 </para>
1464 <para>
1465 <literal>log(2.0, 64.0)</literal>
1466 <returnvalue>6.0000000000000000</returnvalue>
1467 </para></entry>
1468 </row>
1470 <row>
1471 <entry role="func_table_entry"><para role="func_signature">
1472 <indexterm>
1473 <primary>min_scale</primary>
1474 </indexterm>
1475 <function>min_scale</function> ( <type>numeric</type> )
1476 <returnvalue>integer</returnvalue>
1477 </para>
1478 <para>
1479 Minimum scale (number of fractional decimal digits) needed
1480 to represent the supplied value precisely
1481 </para>
1482 <para>
1483 <literal>min_scale(8.4100)</literal>
1484 <returnvalue>2</returnvalue>
1485 </para></entry>
1486 </row>
1488 <row>
1489 <entry role="func_table_entry"><para role="func_signature">
1490 <indexterm>
1491 <primary>mod</primary>
1492 </indexterm>
1493 <function>mod</function> ( <parameter>y</parameter> <replaceable>numeric_type</replaceable>,
1494 <parameter>x</parameter> <replaceable>numeric_type</replaceable> )
1495 <returnvalue><replaceable>numeric_type</replaceable></returnvalue>
1496 </para>
1497 <para>
1498 Remainder of <parameter>y</parameter>/<parameter>x</parameter>;
1499 available for <type>smallint</type>, <type>integer</type>,
1500 <type>bigint</type>, and <type>numeric</type>
1501 </para>
1502 <para>
1503 <literal>mod(9, 4)</literal>
1504 <returnvalue>1</returnvalue>
1505 </para></entry>
1506 </row>
1508 <row>
1509 <entry role="func_table_entry"><para role="func_signature">
1510 <indexterm>
1511 <primary>pi</primary>
1512 </indexterm>
1513 <function>pi</function> ( )
1514 <returnvalue>double precision</returnvalue>
1515 </para>
1516 <para>
1517 Approximate value of <phrase role="symbol_font">&pi;</phrase>
1518 </para>
1519 <para>
1520 <literal>pi()</literal>
1521 <returnvalue>3.141592653589793</returnvalue>
1522 </para></entry>
1523 </row>
1525 <row>
1526 <entry role="func_table_entry"><para role="func_signature">
1527 <indexterm>
1528 <primary>power</primary>
1529 </indexterm>
1530 <function>power</function> ( <parameter>a</parameter> <type>numeric</type>,
1531 <parameter>b</parameter> <type>numeric</type> )
1532 <returnvalue>numeric</returnvalue>
1533 </para>
1534 <para role="func_signature">
1535 <function>power</function> ( <parameter>a</parameter> <type>double precision</type>,
1536 <parameter>b</parameter> <type>double precision</type> )
1537 <returnvalue>double precision</returnvalue>
1538 </para>
1539 <para>
1540 <parameter>a</parameter> raised to the power of <parameter>b</parameter>
1541 </para>
1542 <para>
1543 <literal>power(9, 3)</literal>
1544 <returnvalue>729</returnvalue>
1545 </para></entry>
1546 </row>
1548 <row>
1549 <entry role="func_table_entry"><para role="func_signature">
1550 <indexterm>
1551 <primary>radians</primary>
1552 </indexterm>
1553 <function>radians</function> ( <type>double precision</type> )
1554 <returnvalue>double precision</returnvalue>
1555 </para>
1556 <para>
1557 Converts degrees to radians
1558 </para>
1559 <para>
1560 <literal>radians(45.0)</literal>
1561 <returnvalue>0.7853981633974483</returnvalue>
1562 </para></entry>
1563 </row>
1565 <row>
1566 <entry role="func_table_entry"><para role="func_signature">
1567 <indexterm>
1568 <primary>round</primary>
1569 </indexterm>
1570 <function>round</function> ( <type>numeric</type> )
1571 <returnvalue>numeric</returnvalue>
1572 </para>
1573 <para role="func_signature">
1574 <function>round</function> ( <type>double precision</type> )
1575 <returnvalue>double precision</returnvalue>
1576 </para>
1577 <para>
1578 Rounds to nearest integer. For <type>numeric</type>, ties are
1579 broken by rounding away from zero. For <type>double precision</type>,
1580 the tie-breaking behavior is platform dependent, but
1581 <quote>round to nearest even</quote> is the most common rule.
1582 </para>
1583 <para>
1584 <literal>round(42.4)</literal>
1585 <returnvalue>42</returnvalue>
1586 </para></entry>
1587 </row>
1589 <row>
1590 <entry role="func_table_entry"><para role="func_signature">
1591 <function>round</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> )
1592 <returnvalue>numeric</returnvalue>
1593 </para>
1594 <para>
1595 Rounds <parameter>v</parameter> to <parameter>s</parameter> decimal
1596 places. Ties are broken by rounding away from zero.
1597 </para>
1598 <para>
1599 <literal>round(42.4382, 2)</literal>
1600 <returnvalue>42.44</returnvalue>
1601 </para></entry>
1602 </row>
1604 <row>
1605 <entry role="func_table_entry"><para role="func_signature">
1606 <indexterm>
1607 <primary>scale</primary>
1608 </indexterm>
1609 <function>scale</function> ( <type>numeric</type> )
1610 <returnvalue>integer</returnvalue>
1611 </para>
1612 <para>
1613 Scale of the argument (the number of decimal digits in the fractional part)
1614 </para>
1615 <para>
1616 <literal>scale(8.4100)</literal>
1617 <returnvalue>4</returnvalue>
1618 </para></entry>
1619 </row>
1621 <row>
1622 <entry role="func_table_entry"><para role="func_signature">
1623 <indexterm>
1624 <primary>sign</primary>
1625 </indexterm>
1626 <function>sign</function> ( <type>numeric</type> )
1627 <returnvalue>numeric</returnvalue>
1628 </para>
1629 <para role="func_signature">
1630 <function>sign</function> ( <type>double precision</type> )
1631 <returnvalue>double precision</returnvalue>
1632 </para>
1633 <para>
1634 Sign of the argument (-1, 0, or +1)
1635 </para>
1636 <para>
1637 <literal>sign(-8.4)</literal>
1638 <returnvalue>-1</returnvalue>
1639 </para></entry>
1640 </row>
1642 <row>
1643 <entry role="func_table_entry"><para role="func_signature">
1644 <indexterm>
1645 <primary>sqrt</primary>
1646 </indexterm>
1647 <function>sqrt</function> ( <type>numeric</type> )
1648 <returnvalue>numeric</returnvalue>
1649 </para>
1650 <para role="func_signature">
1651 <function>sqrt</function> ( <type>double precision</type> )
1652 <returnvalue>double precision</returnvalue>
1653 </para>
1654 <para>
1655 Square root
1656 </para>
1657 <para>
1658 <literal>sqrt(2)</literal>
1659 <returnvalue>1.4142135623730951</returnvalue>
1660 </para></entry>
1661 </row>
1663 <row>
1664 <entry role="func_table_entry"><para role="func_signature">
1665 <indexterm>
1666 <primary>trim_scale</primary>
1667 </indexterm>
1668 <function>trim_scale</function> ( <type>numeric</type> )
1669 <returnvalue>numeric</returnvalue>
1670 </para>
1671 <para>
1672 Reduces the value's scale (number of fractional decimal digits) by
1673 removing trailing zeroes
1674 </para>
1675 <para>
1676 <literal>trim_scale(8.4100)</literal>
1677 <returnvalue>8.41</returnvalue>
1678 </para></entry>
1679 </row>
1681 <row>
1682 <entry role="func_table_entry"><para role="func_signature">
1683 <indexterm>
1684 <primary>trunc</primary>
1685 </indexterm>
1686 <function>trunc</function> ( <type>numeric</type> )
1687 <returnvalue>numeric</returnvalue>
1688 </para>
1689 <para role="func_signature">
1690 <function>trunc</function> ( <type>double precision</type> )
1691 <returnvalue>double precision</returnvalue>
1692 </para>
1693 <para>
1694 Truncates to integer (towards zero)
1695 </para>
1696 <para>
1697 <literal>trunc(42.8)</literal>
1698 <returnvalue>42</returnvalue>
1699 </para>
1700 <para>
1701 <literal>trunc(-42.8)</literal>
1702 <returnvalue>-42</returnvalue>
1703 </para></entry>
1704 </row>
1706 <row>
1707 <entry role="func_table_entry"><para role="func_signature">
1708 <function>trunc</function> ( <parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>integer</type> )
1709 <returnvalue>numeric</returnvalue>
1710 </para>
1711 <para>
1712 Truncates <parameter>v</parameter> to <parameter>s</parameter>
1713 decimal places
1714 </para>
1715 <para>
1716 <literal>trunc(42.4382, 2)</literal>
1717 <returnvalue>42.43</returnvalue>
1718 </para></entry>
1719 </row>
1721 <row>
1722 <entry role="func_table_entry"><para role="func_signature">
1723 <indexterm>
1724 <primary>width_bucket</primary>
1725 </indexterm>
1726 <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> )
1727 <returnvalue>integer</returnvalue>
1728 </para>
1729 <para role="func_signature">
1730 <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> )
1731 <returnvalue>integer</returnvalue>
1732 </para>
1733 <para>
1734 Returns the number of the bucket in
1735 which <parameter>operand</parameter> falls in a histogram
1736 having <parameter>count</parameter> equal-width buckets spanning the
1737 range <parameter>low</parameter> to <parameter>high</parameter>.
1738 Returns <literal>0</literal>
1739 or <literal><parameter>count</parameter>+1</literal> for an input
1740 outside that range.
1741 </para>
1742 <para>
1743 <literal>width_bucket(5.35, 0.024, 10.06, 5)</literal>
1744 <returnvalue>3</returnvalue>
1745 </para></entry>
1746 </row>
1748 <row>
1749 <entry role="func_table_entry"><para role="func_signature">
1750 <function>width_bucket</function> ( <parameter>operand</parameter> <type>anycompatible</type>, <parameter>thresholds</parameter> <type>anycompatiblearray</type> )
1751 <returnvalue>integer</returnvalue>
1752 </para>
1753 <para>
1754 Returns the number of the bucket in
1755 which <parameter>operand</parameter> falls given an array listing the
1756 lower bounds of the buckets. Returns <literal>0</literal> for an
1757 input less than the first lower
1758 bound. <parameter>operand</parameter> and the array elements can be
1759 of any type having standard comparison operators.
1760 The <parameter>thresholds</parameter> array <emphasis>must be
1761 sorted</emphasis>, smallest first, or unexpected results will be
1762 obtained.
1763 </para>
1764 <para>
1765 <literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])</literal>
1766 <returnvalue>2</returnvalue>
1767 </para></entry>
1768 </row>
1769 </tbody>
1770 </tgroup>
1771 </table>
1773 <para>
1774 <xref linkend="functions-math-random-table"/> shows functions for
1775 generating random numbers.
1776 </para>
1778 <table id="functions-math-random-table">
1779 <title>Random Functions</title>
1781 <tgroup cols="1">
1782 <thead>
1783 <row>
1784 <entry role="func_table_entry"><para role="func_signature">
1785 Function
1786 </para>
1787 <para>
1788 Description
1789 </para>
1790 <para>
1791 Example(s)
1792 </para></entry>
1793 </row>
1794 </thead>
1796 <tbody>
1797 <row>
1798 <entry role="func_table_entry"><para role="func_signature">
1799 <indexterm>
1800 <primary>random</primary>
1801 </indexterm>
1802 <function>random</function> ( )
1803 <returnvalue>double precision</returnvalue>
1804 </para>
1805 <para>
1806 Returns a random value in the range 0.0 &lt;= x &lt; 1.0
1807 </para>
1808 <para>
1809 <literal>random()</literal>
1810 <returnvalue>0.897124072839091</returnvalue>
1811 </para></entry>
1812 </row>
1814 <row>
1815 <entry role="func_table_entry"><para role="func_signature">
1816 <indexterm>
1817 <primary>setseed</primary>
1818 </indexterm>
1819 <function>setseed</function> ( <type>double precision</type> )
1820 <returnvalue>void</returnvalue>
1821 </para>
1822 <para>
1823 Sets the seed for subsequent <literal>random()</literal> calls;
1824 argument must be between -1.0 and 1.0, inclusive
1825 </para>
1826 <para>
1827 <literal>setseed(0.12345)</literal>
1828 </para></entry>
1829 </row>
1830 </tbody>
1831 </tgroup>
1832 </table>
1834 <para>
1835 The <function>random()</function> function uses a deterministic
1836 pseudo-random number generator.
1837 It is fast but not suitable for cryptographic
1838 applications; see the <xref linkend="pgcrypto"/> module for a more
1839 secure alternative.
1840 If <function>setseed()</function> is called, the series of results of
1841 subsequent <function>random()</function> calls in the current session
1842 can be repeated by re-issuing <function>setseed()</function> with the same
1843 argument.
1844 Without any prior <function>setseed()</function> call in the same
1845 session, the first <function>random()</function> call obtains a seed
1846 from a platform-dependent source of random bits.
1847 </para>
1849 <para>
1850 <xref linkend="functions-math-trig-table"/> shows the
1851 available trigonometric functions. Each of these functions comes in
1852 two variants, one that measures angles in radians and one that
1853 measures angles in degrees.
1854 </para>
1856 <table id="functions-math-trig-table">
1857 <title>Trigonometric Functions</title>
1859 <tgroup cols="1">
1860 <thead>
1861 <row>
1862 <entry role="func_table_entry"><para role="func_signature">
1863 Function
1864 </para>
1865 <para>
1866 Description
1867 </para>
1868 <para>
1869 Example(s)
1870 </para></entry>
1871 </row>
1872 </thead>
1874 <tbody>
1875 <row>
1876 <entry role="func_table_entry"><para role="func_signature">
1877 <indexterm>
1878 <primary>acos</primary>
1879 </indexterm>
1880 <function>acos</function> ( <type>double precision</type> )
1881 <returnvalue>double precision</returnvalue>
1882 </para>
1883 <para>
1884 Inverse cosine, result in radians
1885 </para>
1886 <para>
1887 <literal>acos(1)</literal>
1888 <returnvalue>0</returnvalue>
1889 </para></entry>
1890 </row>
1892 <row>
1893 <entry role="func_table_entry"><para role="func_signature">
1894 <indexterm>
1895 <primary>acosd</primary>
1896 </indexterm>
1897 <function>acosd</function> ( <type>double precision</type> )
1898 <returnvalue>double precision</returnvalue>
1899 </para>
1900 <para>
1901 Inverse cosine, result in degrees
1902 </para>
1903 <para>
1904 <literal>acosd(0.5)</literal>
1905 <returnvalue>60</returnvalue>
1906 </para></entry>
1907 </row>
1909 <row>
1910 <entry role="func_table_entry"><para role="func_signature">
1911 <indexterm>
1912 <primary>asin</primary>
1913 </indexterm>
1914 <function>asin</function> ( <type>double precision</type> )
1915 <returnvalue>double precision</returnvalue>
1916 </para>
1917 <para>
1918 Inverse sine, result in radians
1919 </para>
1920 <para>
1921 <literal>asin(1)</literal>
1922 <returnvalue>1.5707963267948966</returnvalue>
1923 </para></entry>
1924 </row>
1926 <row>
1927 <entry role="func_table_entry"><para role="func_signature">
1928 <indexterm>
1929 <primary>asind</primary>
1930 </indexterm>
1931 <function>asind</function> ( <type>double precision</type> )
1932 <returnvalue>double precision</returnvalue>
1933 </para>
1934 <para>
1935 Inverse sine, result in degrees
1936 </para>
1937 <para>
1938 <literal>asind(0.5)</literal>
1939 <returnvalue>30</returnvalue>
1940 </para></entry>
1941 </row>
1943 <row>
1944 <entry role="func_table_entry"><para role="func_signature">
1945 <indexterm>
1946 <primary>atan</primary>
1947 </indexterm>
1948 <function>atan</function> ( <type>double precision</type> )
1949 <returnvalue>double precision</returnvalue>
1950 </para>
1951 <para>
1952 Inverse tangent, result in radians
1953 </para>
1954 <para>
1955 <literal>atan(1)</literal>
1956 <returnvalue>0.7853981633974483</returnvalue>
1957 </para></entry>
1958 </row>
1960 <row>
1961 <entry role="func_table_entry"><para role="func_signature">
1962 <indexterm>
1963 <primary>atand</primary>
1964 </indexterm>
1965 <function>atand</function> ( <type>double precision</type> )
1966 <returnvalue>double precision</returnvalue>
1967 </para>
1968 <para>
1969 Inverse tangent, result in degrees
1970 </para>
1971 <para>
1972 <literal>atand(1)</literal>
1973 <returnvalue>45</returnvalue>
1974 </para></entry>
1975 </row>
1977 <row>
1978 <entry role="func_table_entry"><para role="func_signature">
1979 <indexterm>
1980 <primary>atan2</primary>
1981 </indexterm>
1982 <function>atan2</function> ( <parameter>y</parameter> <type>double precision</type>,
1983 <parameter>x</parameter> <type>double precision</type> )
1984 <returnvalue>double precision</returnvalue>
1985 </para>
1986 <para>
1987 Inverse tangent of
1988 <parameter>y</parameter>/<parameter>x</parameter>,
1989 result in radians
1990 </para>
1991 <para>
1992 <literal>atan2(1, 0)</literal>
1993 <returnvalue>1.5707963267948966</returnvalue>
1994 </para></entry>
1995 </row>
1997 <row>
1998 <entry role="func_table_entry"><para role="func_signature">
1999 <indexterm>
2000 <primary>atan2d</primary>
2001 </indexterm>
2002 <function>atan2d</function> ( <parameter>y</parameter> <type>double precision</type>,
2003 <parameter>x</parameter> <type>double precision</type> )
2004 <returnvalue>double precision</returnvalue>
2005 </para>
2006 <para>
2007 Inverse tangent of
2008 <parameter>y</parameter>/<parameter>x</parameter>,
2009 result in degrees
2010 </para>
2011 <para>
2012 <literal>atan2d(1, 0)</literal>
2013 <returnvalue>90</returnvalue>
2014 </para></entry>
2015 </row>
2017 <row>
2018 <entry role="func_table_entry"><para role="func_signature">
2019 <indexterm>
2020 <primary>cos</primary>
2021 </indexterm>
2022 <function>cos</function> ( <type>double precision</type> )
2023 <returnvalue>double precision</returnvalue>
2024 </para>
2025 <para>
2026 Cosine, argument in radians
2027 </para>
2028 <para>
2029 <literal>cos(0)</literal>
2030 <returnvalue>1</returnvalue>
2031 </para></entry>
2032 </row>
2034 <row>
2035 <entry role="func_table_entry"><para role="func_signature">
2036 <indexterm>
2037 <primary>cosd</primary>
2038 </indexterm>
2039 <function>cosd</function> ( <type>double precision</type> )
2040 <returnvalue>double precision</returnvalue>
2041 </para>
2042 <para>
2043 Cosine, argument in degrees
2044 </para>
2045 <para>
2046 <literal>cosd(60)</literal>
2047 <returnvalue>0.5</returnvalue>
2048 </para></entry>
2049 </row>
2051 <row>
2052 <entry role="func_table_entry"><para role="func_signature">
2053 <indexterm>
2054 <primary>cot</primary>
2055 </indexterm>
2056 <function>cot</function> ( <type>double precision</type> )
2057 <returnvalue>double precision</returnvalue>
2058 </para>
2059 <para>
2060 Cotangent, argument in radians
2061 </para>
2062 <para>
2063 <literal>cot(0.5)</literal>
2064 <returnvalue>1.830487721712452</returnvalue>
2065 </para></entry>
2066 </row>
2068 <row>
2069 <entry role="func_table_entry"><para role="func_signature">
2070 <indexterm>
2071 <primary>cotd</primary>
2072 </indexterm>
2073 <function>cotd</function> ( <type>double precision</type> )
2074 <returnvalue>double precision</returnvalue>
2075 </para>
2076 <para>
2077 Cotangent, argument in degrees
2078 </para>
2079 <para>
2080 <literal>cotd(45)</literal>
2081 <returnvalue>1</returnvalue>
2082 </para></entry>
2083 </row>
2085 <row>
2086 <entry role="func_table_entry"><para role="func_signature">
2087 <indexterm>
2088 <primary>sin</primary>
2089 </indexterm>
2090 <function>sin</function> ( <type>double precision</type> )
2091 <returnvalue>double precision</returnvalue>
2092 </para>
2093 <para>
2094 Sine, argument in radians
2095 </para>
2096 <para>
2097 <literal>sin(1)</literal>
2098 <returnvalue>0.8414709848078965</returnvalue>
2099 </para></entry>
2100 </row>
2102 <row>
2103 <entry role="func_table_entry"><para role="func_signature">
2104 <indexterm>
2105 <primary>sind</primary>
2106 </indexterm>
2107 <function>sind</function> ( <type>double precision</type> )
2108 <returnvalue>double precision</returnvalue>
2109 </para>
2110 <para>
2111 Sine, argument in degrees
2112 </para>
2113 <para>
2114 <literal>sind(30)</literal>
2115 <returnvalue>0.5</returnvalue>
2116 </para></entry>
2117 </row>
2119 <row>
2120 <entry role="func_table_entry"><para role="func_signature">
2121 <indexterm>
2122 <primary>tan</primary>
2123 </indexterm>
2124 <function>tan</function> ( <type>double precision</type> )
2125 <returnvalue>double precision</returnvalue>
2126 </para>
2127 <para>
2128 Tangent, argument in radians
2129 </para>
2130 <para>
2131 <literal>tan(1)</literal>
2132 <returnvalue>1.5574077246549023</returnvalue>
2133 </para></entry>
2134 </row>
2136 <row>
2137 <entry role="func_table_entry"><para role="func_signature">
2138 <indexterm>
2139 <primary>tand</primary>
2140 </indexterm>
2141 <function>tand</function> ( <type>double precision</type> )
2142 <returnvalue>double precision</returnvalue>
2143 </para>
2144 <para>
2145 Tangent, argument in degrees
2146 </para>
2147 <para>
2148 <literal>tand(45)</literal>
2149 <returnvalue>1</returnvalue>
2150 </para></entry>
2151 </row>
2152 </tbody>
2153 </tgroup>
2154 </table>
2156 <note>
2157 <para>
2158 Another way to work with angles measured in degrees is to use the unit
2159 transformation functions <literal><function>radians()</function></literal>
2160 and <literal><function>degrees()</function></literal> shown earlier.
2161 However, using the degree-based trigonometric functions is preferred,
2162 as that way avoids round-off error for special cases such
2163 as <literal>sind(30)</literal>.
2164 </para>
2165 </note>
2167 <para>
2168 <xref linkend="functions-math-hyp-table"/> shows the
2169 available hyperbolic functions.
2170 </para>
2172 <table id="functions-math-hyp-table">
2173 <title>Hyperbolic Functions</title>
2175 <tgroup cols="1">
2176 <thead>
2177 <row>
2178 <entry role="func_table_entry"><para role="func_signature">
2179 Function
2180 </para>
2181 <para>
2182 Description
2183 </para>
2184 <para>
2185 Example(s)
2186 </para></entry>
2187 </row>
2188 </thead>
2190 <tbody>
2191 <row>
2192 <entry role="func_table_entry"><para role="func_signature">
2193 <indexterm>
2194 <primary>sinh</primary>
2195 </indexterm>
2196 <function>sinh</function> ( <type>double precision</type> )
2197 <returnvalue>double precision</returnvalue>
2198 </para>
2199 <para>
2200 Hyperbolic sine
2201 </para>
2202 <para>
2203 <literal>sinh(1)</literal>
2204 <returnvalue>1.1752011936438014</returnvalue>
2205 </para></entry>
2206 </row>
2208 <row>
2209 <entry role="func_table_entry"><para role="func_signature">
2210 <indexterm>
2211 <primary>cosh</primary>
2212 </indexterm>
2213 <function>cosh</function> ( <type>double precision</type> )
2214 <returnvalue>double precision</returnvalue>
2215 </para>
2216 <para>
2217 Hyperbolic cosine
2218 </para>
2219 <para>
2220 <literal>cosh(0)</literal>
2221 <returnvalue>1</returnvalue>
2222 </para></entry>
2223 </row>
2225 <row>
2226 <entry role="func_table_entry"><para role="func_signature">
2227 <indexterm>
2228 <primary>tanh</primary>
2229 </indexterm>
2230 <function>tanh</function> ( <type>double precision</type> )
2231 <returnvalue>double precision</returnvalue>
2232 </para>
2233 <para>
2234 Hyperbolic tangent
2235 </para>
2236 <para>
2237 <literal>tanh(1)</literal>
2238 <returnvalue>0.7615941559557649</returnvalue>
2239 </para></entry>
2240 </row>
2242 <row>
2243 <entry role="func_table_entry"><para role="func_signature">
2244 <indexterm>
2245 <primary>asinh</primary>
2246 </indexterm>
2247 <function>asinh</function> ( <type>double precision</type> )
2248 <returnvalue>double precision</returnvalue>
2249 </para>
2250 <para>
2251 Inverse hyperbolic sine
2252 </para>
2253 <para>
2254 <literal>asinh(1)</literal>
2255 <returnvalue>0.881373587019543</returnvalue>
2256 </para></entry>
2257 </row>
2259 <row>
2260 <entry role="func_table_entry"><para role="func_signature">
2261 <indexterm>
2262 <primary>acosh</primary>
2263 </indexterm>
2264 <function>acosh</function> ( <type>double precision</type> )
2265 <returnvalue>double precision</returnvalue>
2266 </para>
2267 <para>
2268 Inverse hyperbolic cosine
2269 </para>
2270 <para>
2271 <literal>acosh(1)</literal>
2272 <returnvalue>0</returnvalue>
2273 </para></entry>
2274 </row>
2276 <row>
2277 <entry role="func_table_entry"><para role="func_signature">
2278 <indexterm>
2279 <primary>atanh</primary>
2280 </indexterm>
2281 <function>atanh</function> ( <type>double precision</type> )
2282 <returnvalue>double precision</returnvalue>
2283 </para>
2284 <para>
2285 Inverse hyperbolic tangent
2286 </para>
2287 <para>
2288 <literal>atanh(0.5)</literal>
2289 <returnvalue>0.5493061443340548</returnvalue>
2290 </para></entry>
2291 </row>
2292 </tbody>
2293 </tgroup>
2294 </table>
2296 </sect1>
2299 <sect1 id="functions-string">
2300 <title>String Functions and Operators</title>
2302 <para>
2303 This section describes functions and operators for examining and
2304 manipulating string values. Strings in this context include values
2305 of the types <type>character</type>, <type>character varying</type>,
2306 and <type>text</type>. Except where noted, these functions and operators
2307 are declared to accept and return type <type>text</type>. They will
2308 interchangeably accept <type>character varying</type> arguments.
2309 Values of type <type>character</type> will be converted
2310 to <type>text</type> before the function or operator is applied, resulting
2311 in stripping any trailing spaces in the <type>character</type> value.
2312 </para>
2314 <para>
2315 <acronym>SQL</acronym> defines some string functions that use
2316 key words, rather than commas, to separate
2317 arguments. Details are in
2318 <xref linkend="functions-string-sql"/>.
2319 <productname>PostgreSQL</productname> also provides versions of these functions
2320 that use the regular function invocation syntax
2321 (see <xref linkend="functions-string-other"/>).
2322 </para>
2324 <note>
2325 <para>
2326 The string concatenation operator (<literal>||</literal>) will accept
2327 non-string input, so long as at least one input is of string type, as shown
2328 in <xref linkend="functions-string-sql"/>. For other cases, inserting an
2329 explicit coercion to <type>text</type> can be used to have non-string input
2330 accepted.
2331 </para>
2332 </note>
2334 <table id="functions-string-sql">
2335 <title><acronym>SQL</acronym> String Functions and Operators</title>
2336 <tgroup cols="1">
2337 <thead>
2338 <row>
2339 <entry role="func_table_entry"><para role="func_signature">
2340 Function/Operator
2341 </para>
2342 <para>
2343 Description
2344 </para>
2345 <para>
2346 Example(s)
2347 </para></entry>
2348 </row>
2349 </thead>
2351 <tbody>
2352 <row>
2353 <entry role="func_table_entry"><para role="func_signature">
2354 <indexterm>
2355 <primary>character string</primary>
2356 <secondary>concatenation</secondary>
2357 </indexterm>
2358 <type>text</type> <literal>||</literal> <type>text</type>
2359 <returnvalue>text</returnvalue>
2360 </para>
2361 <para>
2362 Concatenates the two strings.
2363 </para>
2364 <para>
2365 <literal>'Post' || 'greSQL'</literal>
2366 <returnvalue>PostgreSQL</returnvalue>
2367 </para></entry>
2368 </row>
2370 <row>
2371 <entry role="func_table_entry"><para role="func_signature">
2372 <type>text</type> <literal>||</literal> <type>anynonarray</type>
2373 <returnvalue>text</returnvalue>
2374 </para>
2375 <para role="func_signature">
2376 <type>anynonarray</type> <literal>||</literal> <type>text</type>
2377 <returnvalue>text</returnvalue>
2378 </para>
2379 <para>
2380 Converts the non-string input to text, then concatenates the two
2381 strings. (The non-string input cannot be of an array type, because
2382 that would create ambiguity with the array <literal>||</literal>
2383 operators. If you want to concatenate an array's text equivalent,
2384 cast it to <type>text</type> explicitly.)
2385 </para>
2386 <para>
2387 <literal>'Value: ' || 42</literal>
2388 <returnvalue>Value: 42</returnvalue>
2389 </para></entry>
2390 </row>
2392 <row>
2393 <entry role="func_table_entry"><para role="func_signature">
2394 <indexterm>
2395 <primary>normalized</primary>
2396 </indexterm>
2397 <indexterm>
2398 <primary>Unicode normalization</primary>
2399 </indexterm>
2400 <type>text</type> <literal>IS</literal> <optional><literal>NOT</literal></optional> <optional><parameter>form</parameter></optional> <literal>NORMALIZED</literal>
2401 <returnvalue>boolean</returnvalue>
2402 </para>
2403 <para>
2404 Checks whether the string is in the specified Unicode normalization
2405 form. The optional <parameter>form</parameter> key word specifies the
2406 form: <literal>NFC</literal> (the default), <literal>NFD</literal>,
2407 <literal>NFKC</literal>, or <literal>NFKD</literal>. This expression can
2408 only be used when the server encoding is <literal>UTF8</literal>. Note
2409 that checking for normalization using this expression is often faster
2410 than normalizing possibly already normalized strings.
2411 </para>
2412 <para>
2413 <literal>U&amp;'\0061\0308bc' IS NFD NORMALIZED</literal>
2414 <returnvalue>t</returnvalue>
2415 </para></entry>
2416 </row>
2418 <row>
2419 <entry role="func_table_entry"><para role="func_signature">
2420 <indexterm>
2421 <primary>bit_length</primary>
2422 </indexterm>
2423 <function>bit_length</function> ( <type>text</type> )
2424 <returnvalue>integer</returnvalue>
2425 </para>
2426 <para>
2427 Returns number of bits in the string (8
2428 times the <function>octet_length</function>).
2429 </para>
2430 <para>
2431 <literal>bit_length('jose')</literal>
2432 <returnvalue>32</returnvalue>
2433 </para></entry>
2434 </row>
2436 <row>
2437 <entry role="func_table_entry"><para role="func_signature">
2438 <indexterm>
2439 <primary>char_length</primary>
2440 </indexterm>
2441 <indexterm>
2442 <primary>character string</primary>
2443 <secondary>length</secondary>
2444 </indexterm>
2445 <indexterm>
2446 <primary>length</primary>
2447 <secondary sortas="character string">of a character string</secondary>
2448 <see>character string, length</see>
2449 </indexterm>
2450 <function>char_length</function> ( <type>text</type> )
2451 <returnvalue>integer</returnvalue>
2452 </para>
2453 <para role="func_signature">
2454 <indexterm>
2455 <primary>character_length</primary>
2456 </indexterm>
2457 <function>character_length</function> ( <type>text</type> )
2458 <returnvalue>integer</returnvalue>
2459 </para>
2460 <para>
2461 Returns number of characters in the string.
2462 </para>
2463 <para>
2464 <literal>char_length('jos&eacute;')</literal>
2465 <returnvalue>4</returnvalue>
2466 </para></entry>
2467 </row>
2469 <row>
2470 <entry role="func_table_entry"><para role="func_signature">
2471 <indexterm>
2472 <primary>lower</primary>
2473 </indexterm>
2474 <function>lower</function> ( <type>text</type> )
2475 <returnvalue>text</returnvalue>
2476 </para>
2477 <para>
2478 Converts the string to all lower case, according to the rules of the
2479 database's locale.
2480 </para>
2481 <para>
2482 <literal>lower('TOM')</literal>
2483 <returnvalue>tom</returnvalue>
2484 </para></entry>
2485 </row>
2487 <row>
2488 <entry role="func_table_entry"><para role="func_signature">
2489 <indexterm>
2490 <primary>normalize</primary>
2491 </indexterm>
2492 <indexterm>
2493 <primary>Unicode normalization</primary>
2494 </indexterm>
2495 <function>normalize</function> ( <type>text</type>
2496 <optional>, <parameter>form</parameter> </optional> )
2497 <returnvalue>text</returnvalue>
2498 </para>
2499 <para>
2500 Converts the string to the specified Unicode
2501 normalization form. The optional <parameter>form</parameter> key word
2502 specifies the form: <literal>NFC</literal> (the default),
2503 <literal>NFD</literal>, <literal>NFKC</literal>, or
2504 <literal>NFKD</literal>. This function can only be used when the
2505 server encoding is <literal>UTF8</literal>.
2506 </para>
2507 <para>
2508 <literal>normalize(U&amp;'\0061\0308bc', NFC)</literal>
2509 <returnvalue>U&amp;'\00E4bc'</returnvalue>
2510 </para></entry>
2511 </row>
2513 <row>
2514 <entry role="func_table_entry"><para role="func_signature">
2515 <indexterm>
2516 <primary>octet_length</primary>
2517 </indexterm>
2518 <function>octet_length</function> ( <type>text</type> )
2519 <returnvalue>integer</returnvalue>
2520 </para>
2521 <para>
2522 Returns number of bytes in the string.
2523 </para>
2524 <para>
2525 <literal>octet_length('jos&eacute;')</literal>
2526 <returnvalue>5</returnvalue> (if server encoding is UTF8)
2527 </para></entry>
2528 </row>
2530 <row>
2531 <entry role="func_table_entry"><para role="func_signature">
2532 <indexterm>
2533 <primary>octet_length</primary>
2534 </indexterm>
2535 <function>octet_length</function> ( <type>character</type> )
2536 <returnvalue>integer</returnvalue>
2537 </para>
2538 <para>
2539 Returns number of bytes in the string. Since this version of the
2540 function accepts type <type>character</type> directly, it will not
2541 strip trailing spaces.
2542 </para>
2543 <para>
2544 <literal>octet_length('abc '::character(4))</literal>
2545 <returnvalue>4</returnvalue>
2546 </para></entry>
2547 </row>
2549 <row>
2550 <entry role="func_table_entry"><para role="func_signature">
2551 <indexterm>
2552 <primary>overlay</primary>
2553 </indexterm>
2554 <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> )
2555 <returnvalue>text</returnvalue>
2556 </para>
2557 <para>
2558 Replaces the substring of <parameter>string</parameter> that starts at
2559 the <parameter>start</parameter>'th character and extends
2560 for <parameter>count</parameter> characters
2561 with <parameter>newsubstring</parameter>.
2562 If <parameter>count</parameter> is omitted, it defaults to the length
2563 of <parameter>newsubstring</parameter>.
2564 </para>
2565 <para>
2566 <literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal>
2567 <returnvalue>Thomas</returnvalue>
2568 </para></entry>
2569 </row>
2571 <row>
2572 <entry role="func_table_entry"><para role="func_signature">
2573 <indexterm>
2574 <primary>position</primary>
2575 </indexterm>
2576 <function>position</function> ( <parameter>substring</parameter> <type>text</type> <literal>IN</literal> <parameter>string</parameter> <type>text</type> )
2577 <returnvalue>integer</returnvalue>
2578 </para>
2579 <para>
2580 Returns first starting index of the specified
2581 <parameter>substring</parameter> within
2582 <parameter>string</parameter>, or zero if it's not present.
2583 </para>
2584 <para>
2585 <literal>position('om' in 'Thomas')</literal>
2586 <returnvalue>3</returnvalue>
2587 </para></entry>
2588 </row>
2590 <row>
2591 <entry role="func_table_entry"><para role="func_signature">
2592 <indexterm>
2593 <primary>substring</primary>
2594 </indexterm>
2595 <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> )
2596 <returnvalue>text</returnvalue>
2597 </para>
2598 <para>
2599 Extracts the substring of <parameter>string</parameter> starting at
2600 the <parameter>start</parameter>'th character if that is specified,
2601 and stopping after <parameter>count</parameter> characters if that is
2602 specified. Provide at least one of <parameter>start</parameter>
2603 and <parameter>count</parameter>.
2604 </para>
2605 <para>
2606 <literal>substring('Thomas' from 2 for 3)</literal>
2607 <returnvalue>hom</returnvalue>
2608 </para>
2609 <para>
2610 <literal>substring('Thomas' from 3)</literal>
2611 <returnvalue>omas</returnvalue>
2612 </para>
2613 <para>
2614 <literal>substring('Thomas' for 2)</literal>
2615 <returnvalue>Th</returnvalue>
2616 </para></entry>
2617 </row>
2619 <row>
2620 <entry role="func_table_entry"><para role="func_signature">
2621 <function>substring</function> ( <parameter>string</parameter> <type>text</type> <literal>FROM</literal> <parameter>pattern</parameter> <type>text</type> )
2622 <returnvalue>text</returnvalue>
2623 </para>
2624 <para>
2625 Extracts the first substring matching POSIX regular expression; see
2626 <xref linkend="functions-posix-regexp"/>.
2627 </para>
2628 <para>
2629 <literal>substring('Thomas' from '...$')</literal>
2630 <returnvalue>mas</returnvalue>
2631 </para></entry>
2632 </row>
2634 <row>
2635 <entry role="func_table_entry"><para role="func_signature">
2636 <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> )
2637 <returnvalue>text</returnvalue>
2638 </para>
2639 <para role="func_signature">
2640 <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> )
2641 <returnvalue>text</returnvalue>
2642 </para>
2643 <para>
2644 Extracts the first substring matching <acronym>SQL</acronym> regular expression;
2645 see <xref linkend="functions-similarto-regexp"/>. The first form has
2646 been specified since SQL:2003; the second form was only in SQL:1999
2647 and should be considered obsolete.
2648 </para>
2649 <para>
2650 <literal>substring('Thomas' similar '%#"o_a#"_' escape '#')</literal>
2651 <returnvalue>oma</returnvalue>
2652 </para></entry>
2653 </row>
2655 <row>
2656 <entry role="func_table_entry"><para role="func_signature">
2657 <indexterm>
2658 <primary>trim</primary>
2659 </indexterm>
2660 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
2661 <optional> <parameter>characters</parameter> <type>text</type> </optional> <literal>FROM</literal>
2662 <parameter>string</parameter> <type>text</type> )
2663 <returnvalue>text</returnvalue>
2664 </para>
2665 <para>
2666 Removes the longest string containing only characters in
2667 <parameter>characters</parameter> (a space by default) from the
2668 start, end, or both ends (<literal>BOTH</literal> is the default)
2669 of <parameter>string</parameter>.
2670 </para>
2671 <para>
2672 <literal>trim(both 'xyz' from 'yxTomxx')</literal>
2673 <returnvalue>Tom</returnvalue>
2674 </para></entry>
2675 </row>
2677 <row>
2678 <entry role="func_table_entry"><para role="func_signature">
2679 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
2680 <parameter>string</parameter> <type>text</type> <optional>,
2681 <parameter>characters</parameter> <type>text</type> </optional> )
2682 <returnvalue>text</returnvalue>
2683 </para>
2684 <para>
2685 This is a non-standard syntax for <function>trim()</function>.
2686 </para>
2687 <para>
2688 <literal>trim(both from 'yxTomxx', 'xyz')</literal>
2689 <returnvalue>Tom</returnvalue>
2690 </para></entry>
2691 </row>
2693 <row>
2694 <entry role="func_table_entry"><para role="func_signature">
2695 <indexterm>
2696 <primary>upper</primary>
2697 </indexterm>
2698 <function>upper</function> ( <type>text</type> )
2699 <returnvalue>text</returnvalue>
2700 </para>
2701 <para>
2702 Converts the string to all upper case, according to the rules of the
2703 database's locale.
2704 </para>
2705 <para>
2706 <literal>upper('tom')</literal>
2707 <returnvalue>TOM</returnvalue>
2708 </para></entry>
2709 </row>
2710 </tbody>
2711 </tgroup>
2712 </table>
2714 <para>
2715 Additional string manipulation functions and operators are available
2716 and are listed in <xref linkend="functions-string-other"/>. (Some of
2717 these are used internally to implement
2718 the <acronym>SQL</acronym>-standard string functions listed in
2719 <xref linkend="functions-string-sql"/>.)
2720 There are also pattern-matching operators, which are described in
2721 <xref linkend="functions-matching"/>, and operators for full-text
2722 search, which are described in <xref linkend="textsearch"/>.
2723 </para>
2725 <table id="functions-string-other">
2726 <title>Other String Functions and Operators</title>
2727 <tgroup cols="1">
2728 <thead>
2729 <row>
2730 <entry role="func_table_entry"><para role="func_signature">
2731 Function/Operator
2732 </para>
2733 <para>
2734 Description
2735 </para>
2736 <para>
2737 Example(s)
2738 </para></entry>
2739 </row>
2740 </thead>
2742 <tbody>
2743 <row>
2744 <entry role="func_table_entry"><para role="func_signature">
2745 <indexterm>
2746 <primary>character string</primary>
2747 <secondary>prefix test</secondary>
2748 </indexterm>
2749 <type>text</type> <literal>^@</literal> <type>text</type>
2750 <returnvalue>boolean</returnvalue>
2751 </para>
2752 <para>
2753 Returns true if the first string starts with the second string
2754 (equivalent to the <function>starts_with()</function> function).
2755 </para>
2756 <para>
2757 <literal>'alphabet' ^@ 'alph'</literal>
2758 <returnvalue>t</returnvalue>
2759 </para></entry>
2760 </row>
2762 <row>
2763 <entry role="func_table_entry"><para role="func_signature">
2764 <indexterm>
2765 <primary>ascii</primary>
2766 </indexterm>
2767 <function>ascii</function> ( <type>text</type> )
2768 <returnvalue>integer</returnvalue>
2769 </para>
2770 <para>
2771 Returns the numeric code of the first character of the argument.
2772 In <acronym>UTF8</acronym> encoding, returns the Unicode code point
2773 of the character. In other multibyte encodings, the argument must
2774 be an <acronym>ASCII</acronym> character.
2775 </para>
2776 <para>
2777 <literal>ascii('x')</literal>
2778 <returnvalue>120</returnvalue>
2779 </para></entry>
2780 </row>
2782 <row>
2783 <entry role="func_table_entry"><para role="func_signature">
2784 <indexterm>
2785 <primary>btrim</primary>
2786 </indexterm>
2787 <function>btrim</function> ( <parameter>string</parameter> <type>text</type>
2788 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2789 <returnvalue>text</returnvalue>
2790 </para>
2791 <para>
2792 Removes the longest string containing only characters
2793 in <parameter>characters</parameter> (a space by default)
2794 from the start and end of <parameter>string</parameter>.
2795 </para>
2796 <para>
2797 <literal>btrim('xyxtrimyyx', 'xyz')</literal>
2798 <returnvalue>trim</returnvalue>
2799 </para></entry>
2800 </row>
2802 <row>
2803 <entry role="func_table_entry"><para role="func_signature">
2804 <indexterm>
2805 <primary>chr</primary>
2806 </indexterm>
2807 <function>chr</function> ( <type>integer</type> )
2808 <returnvalue>text</returnvalue>
2809 </para>
2810 <para>
2811 Returns the character with the given code. In <acronym>UTF8</acronym>
2812 encoding the argument is treated as a Unicode code point. In other
2813 multibyte encodings the argument must designate
2814 an <acronym>ASCII</acronym> character. <literal>chr(0)</literal> is
2815 disallowed because text data types cannot store that character.
2816 </para>
2817 <para>
2818 <literal>chr(65)</literal>
2819 <returnvalue>A</returnvalue>
2820 </para></entry>
2821 </row>
2823 <row>
2824 <entry role="func_table_entry"><para role="func_signature">
2825 <indexterm>
2826 <primary>concat</primary>
2827 </indexterm>
2828 <function>concat</function> ( <parameter>val1</parameter> <type>"any"</type>
2829 [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] )
2830 <returnvalue>text</returnvalue>
2831 </para>
2832 <para>
2833 Concatenates the text representations of all the arguments.
2834 NULL arguments are ignored.
2835 </para>
2836 <para>
2837 <literal>concat('abcde', 2, NULL, 22)</literal>
2838 <returnvalue>abcde222</returnvalue>
2839 </para></entry>
2840 </row>
2842 <row>
2843 <entry role="func_table_entry"><para role="func_signature">
2844 <indexterm>
2845 <primary>concat_ws</primary>
2846 </indexterm>
2847 <function>concat_ws</function> ( <parameter>sep</parameter> <type>text</type>,
2848 <parameter>val1</parameter> <type>"any"</type>
2849 [, <parameter>val2</parameter> <type>"any"</type> [, ...] ] )
2850 <returnvalue>text</returnvalue>
2851 </para>
2852 <para>
2853 Concatenates all but the first argument, with separators. The first
2854 argument is used as the separator string, and should not be NULL.
2855 Other NULL arguments are ignored.
2856 </para>
2857 <para>
2858 <literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal>
2859 <returnvalue>abcde,2,22</returnvalue>
2860 </para></entry>
2861 </row>
2863 <row>
2864 <entry role="func_table_entry"><para role="func_signature">
2865 <indexterm>
2866 <primary>format</primary>
2867 </indexterm>
2868 <function>format</function> ( <parameter>formatstr</parameter> <type>text</type>
2869 [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ] )
2870 <returnvalue>text</returnvalue>
2871 </para>
2872 <para>
2873 Formats arguments according to a format string;
2874 see <xref linkend="functions-string-format"/>.
2875 This function is similar to the C function <function>sprintf</function>.
2876 </para>
2877 <para>
2878 <literal>format('Hello %s, %1$s', 'World')</literal>
2879 <returnvalue>Hello World, World</returnvalue>
2880 </para></entry>
2881 </row>
2883 <row>
2884 <entry role="func_table_entry"><para role="func_signature">
2885 <indexterm>
2886 <primary>initcap</primary>
2887 </indexterm>
2888 <function>initcap</function> ( <type>text</type> )
2889 <returnvalue>text</returnvalue>
2890 </para>
2891 <para>
2892 Converts the first letter of each word to upper case and the
2893 rest to lower case. Words are sequences of alphanumeric
2894 characters separated by non-alphanumeric characters.
2895 </para>
2896 <para>
2897 <literal>initcap('hi THOMAS')</literal>
2898 <returnvalue>Hi Thomas</returnvalue>
2899 </para></entry>
2900 </row>
2902 <row>
2903 <entry role="func_table_entry"><para role="func_signature">
2904 <indexterm>
2905 <primary>left</primary>
2906 </indexterm>
2907 <function>left</function> ( <parameter>string</parameter> <type>text</type>,
2908 <parameter>n</parameter> <type>integer</type> )
2909 <returnvalue>text</returnvalue>
2910 </para>
2911 <para>
2912 Returns first <parameter>n</parameter> characters in the
2913 string, or when <parameter>n</parameter> is negative, returns
2914 all but last |<parameter>n</parameter>| characters.
2915 </para>
2916 <para>
2917 <literal>left('abcde', 2)</literal>
2918 <returnvalue>ab</returnvalue>
2919 </para></entry>
2920 </row>
2922 <row>
2923 <entry role="func_table_entry"><para role="func_signature">
2924 <indexterm>
2925 <primary>length</primary>
2926 </indexterm>
2927 <function>length</function> ( <type>text</type> )
2928 <returnvalue>integer</returnvalue>
2929 </para>
2930 <para>
2931 Returns the number of characters in the string.
2932 </para>
2933 <para>
2934 <literal>length('jose')</literal>
2935 <returnvalue>4</returnvalue>
2936 </para></entry>
2937 </row>
2939 <row>
2940 <entry role="func_table_entry"><para role="func_signature">
2941 <indexterm>
2942 <primary>lpad</primary>
2943 </indexterm>
2944 <function>lpad</function> ( <parameter>string</parameter> <type>text</type>,
2945 <parameter>length</parameter> <type>integer</type>
2946 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
2947 <returnvalue>text</returnvalue>
2948 </para>
2949 <para>
2950 Extends the <parameter>string</parameter> to length
2951 <parameter>length</parameter> by prepending the characters
2952 <parameter>fill</parameter> (a space by default). If the
2953 <parameter>string</parameter> is already longer than
2954 <parameter>length</parameter> then it is truncated (on the right).
2955 </para>
2956 <para>
2957 <literal>lpad('hi', 5, 'xy')</literal>
2958 <returnvalue>xyxhi</returnvalue>
2959 </para></entry>
2960 </row>
2962 <row>
2963 <entry role="func_table_entry"><para role="func_signature">
2964 <indexterm>
2965 <primary>ltrim</primary>
2966 </indexterm>
2967 <function>ltrim</function> ( <parameter>string</parameter> <type>text</type>
2968 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
2969 <returnvalue>text</returnvalue>
2970 </para>
2971 <para>
2972 Removes the longest string containing only characters in
2973 <parameter>characters</parameter> (a space by default) from the start of
2974 <parameter>string</parameter>.
2975 </para>
2976 <para>
2977 <literal>ltrim('zzzytest', 'xyz')</literal>
2978 <returnvalue>test</returnvalue>
2979 </para></entry>
2980 </row>
2982 <row>
2983 <entry role="func_table_entry"><para role="func_signature">
2984 <indexterm>
2985 <primary>md5</primary>
2986 </indexterm>
2987 <function>md5</function> ( <type>text</type> )
2988 <returnvalue>text</returnvalue>
2989 </para>
2990 <para>
2991 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
2992 the argument, with the result written in hexadecimal.
2993 </para>
2994 <para>
2995 <literal>md5('abc')</literal>
2996 <returnvalue>900150983cd24fb0&zwsp;d6963f7d28e17f72</returnvalue>
2997 </para></entry>
2998 </row>
3000 <row>
3001 <entry role="func_table_entry"><para role="func_signature">
3002 <indexterm>
3003 <primary>parse_ident</primary>
3004 </indexterm>
3005 <function>parse_ident</function> ( <parameter>qualified_identifier</parameter> <type>text</type>
3006 [, <parameter>strict_mode</parameter> <type>boolean</type> <literal>DEFAULT</literal> <literal>true</literal> ] )
3007 <returnvalue>text[]</returnvalue>
3008 </para>
3009 <para>
3010 Splits <parameter>qualified_identifier</parameter> into an array of
3011 identifiers, removing any quoting of individual identifiers. By
3012 default, extra characters after the last identifier are considered an
3013 error; but if the second parameter is <literal>false</literal>, then such
3014 extra characters are ignored. (This behavior is useful for parsing
3015 names for objects like functions.) Note that this function does not
3016 truncate over-length identifiers. If you want truncation you can cast
3017 the result to <type>name[]</type>.
3018 </para>
3019 <para>
3020 <literal>parse_ident('"SomeSchema".someTable')</literal>
3021 <returnvalue>{SomeSchema,sometable}</returnvalue>
3022 </para></entry>
3023 </row>
3025 <row>
3026 <entry role="func_table_entry"><para role="func_signature">
3027 <indexterm>
3028 <primary>pg_client_encoding</primary>
3029 </indexterm>
3030 <function>pg_client_encoding</function> ( )
3031 <returnvalue>name</returnvalue>
3032 </para>
3033 <para>
3034 Returns current client encoding name.
3035 </para>
3036 <para>
3037 <literal>pg_client_encoding()</literal>
3038 <returnvalue>UTF8</returnvalue>
3039 </para></entry>
3040 </row>
3042 <row>
3043 <entry role="func_table_entry"><para role="func_signature">
3044 <indexterm>
3045 <primary>quote_ident</primary>
3046 </indexterm>
3047 <function>quote_ident</function> ( <type>text</type> )
3048 <returnvalue>text</returnvalue>
3049 </para>
3050 <para>
3051 Returns the given string suitably quoted to be used as an identifier
3052 in an <acronym>SQL</acronym> statement string.
3053 Quotes are added only if necessary (i.e., if the string contains
3054 non-identifier characters or would be case-folded).
3055 Embedded quotes are properly doubled.
3056 See also <xref linkend="plpgsql-quote-literal-example"/>.
3057 </para>
3058 <para>
3059 <literal>quote_ident('Foo bar')</literal>
3060 <returnvalue>"Foo bar"</returnvalue>
3061 </para></entry>
3062 </row>
3064 <row>
3065 <entry role="func_table_entry"><para role="func_signature">
3066 <indexterm>
3067 <primary>quote_literal</primary>
3068 </indexterm>
3069 <function>quote_literal</function> ( <type>text</type> )
3070 <returnvalue>text</returnvalue>
3071 </para>
3072 <para>
3073 Returns the given string suitably quoted to be used as a string literal
3074 in an <acronym>SQL</acronym> statement string.
3075 Embedded single-quotes and backslashes are properly doubled.
3076 Note that <function>quote_literal</function> returns null on null
3077 input; if the argument might be null,
3078 <function>quote_nullable</function> is often more suitable.
3079 See also <xref linkend="plpgsql-quote-literal-example"/>.
3080 </para>
3081 <para>
3082 <literal>quote_literal(E'O\'Reilly')</literal>
3083 <returnvalue>'O''Reilly'</returnvalue>
3084 </para></entry>
3085 </row>
3087 <row>
3088 <entry role="func_table_entry"><para role="func_signature">
3089 <function>quote_literal</function> ( <type>anyelement</type> )
3090 <returnvalue>text</returnvalue>
3091 </para>
3092 <para>
3093 Converts the given value to text and then quotes it as a literal.
3094 Embedded single-quotes and backslashes are properly doubled.
3095 </para>
3096 <para>
3097 <literal>quote_literal(42.5)</literal>
3098 <returnvalue>'42.5'</returnvalue>
3099 </para></entry>
3100 </row>
3102 <row>
3103 <entry role="func_table_entry"><para role="func_signature">
3104 <indexterm>
3105 <primary>quote_nullable</primary>
3106 </indexterm>
3107 <function>quote_nullable</function> ( <type>text</type> )
3108 <returnvalue>text</returnvalue>
3109 </para>
3110 <para>
3111 Returns the given string suitably quoted to be used as a string literal
3112 in an <acronym>SQL</acronym> statement string; or, if the argument
3113 is null, returns <literal>NULL</literal>.
3114 Embedded single-quotes and backslashes are properly doubled.
3115 See also <xref linkend="plpgsql-quote-literal-example"/>.
3116 </para>
3117 <para>
3118 <literal>quote_nullable(NULL)</literal>
3119 <returnvalue>NULL</returnvalue>
3120 </para></entry>
3121 </row>
3123 <row>
3124 <entry role="func_table_entry"><para role="func_signature">
3125 <function>quote_nullable</function> ( <type>anyelement</type> )
3126 <returnvalue>text</returnvalue>
3127 </para>
3128 <para>
3129 Converts the given value to text and then quotes it as a literal;
3130 or, if the argument is null, returns <literal>NULL</literal>.
3131 Embedded single-quotes and backslashes are properly doubled.
3132 </para>
3133 <para>
3134 <literal>quote_nullable(42.5)</literal>
3135 <returnvalue>'42.5'</returnvalue>
3136 </para></entry>
3137 </row>
3139 <row>
3140 <entry role="func_table_entry"><para role="func_signature">
3141 <indexterm>
3142 <primary>regexp_count</primary>
3143 </indexterm>
3144 <function>regexp_count</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3145 [, <parameter>start</parameter> <type>integer</type>
3146 [, <parameter>flags</parameter> <type>text</type> ] ] )
3147 <returnvalue>integer</returnvalue>
3148 </para>
3149 <para>
3150 Returns the number of times the POSIX regular
3151 expression <parameter>pattern</parameter> matches in
3152 the <parameter>string</parameter>; see
3153 <xref linkend="functions-posix-regexp"/>.
3154 </para>
3155 <para>
3156 <literal>regexp_count('123456789012', '\d\d\d', 2)</literal>
3157 <returnvalue>3</returnvalue>
3158 </para></entry>
3159 </row>
3161 <row>
3162 <entry role="func_table_entry"><para role="func_signature">
3163 <indexterm>
3164 <primary>regexp_instr</primary>
3165 </indexterm>
3166 <function>regexp_instr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3167 [, <parameter>start</parameter> <type>integer</type>
3168 [, <parameter>N</parameter> <type>integer</type>
3169 [, <parameter>endoption</parameter> <type>integer</type>
3170 [, <parameter>flags</parameter> <type>text</type>
3171 [, <parameter>subexpr</parameter> <type>integer</type> ] ] ] ] ] )
3172 <returnvalue>integer</returnvalue>
3173 </para>
3174 <para>
3175 Returns the position within <parameter>string</parameter> where
3176 the <parameter>N</parameter>'th match of the POSIX regular
3177 expression <parameter>pattern</parameter> occurs, or zero if there is
3178 no such match; see <xref linkend="functions-posix-regexp"/>.
3179 </para>
3180 <para>
3181 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i')</literal>
3182 <returnvalue>3</returnvalue>
3183 </para>
3184 <para>
3185 <literal>regexp_instr('ABCDEF', 'c(.)(..)', 1, 1, 0, 'i', 2)</literal>
3186 <returnvalue>5</returnvalue>
3187 </para></entry>
3188 </row>
3190 <row>
3191 <entry role="func_table_entry"><para role="func_signature">
3192 <indexterm>
3193 <primary>regexp_like</primary>
3194 </indexterm>
3195 <function>regexp_like</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3196 [, <parameter>flags</parameter> <type>text</type> ] )
3197 <returnvalue>boolean</returnvalue>
3198 </para>
3199 <para>
3200 Checks whether a match of the POSIX regular
3201 expression <parameter>pattern</parameter> occurs
3202 within <parameter>string</parameter>; see
3203 <xref linkend="functions-posix-regexp"/>.
3204 </para>
3205 <para>
3206 <literal>regexp_like('Hello World', 'world$', 'i')</literal>
3207 <returnvalue>t</returnvalue>
3208 </para></entry>
3209 </row>
3211 <row>
3212 <entry role="func_table_entry"><para role="func_signature">
3213 <indexterm>
3214 <primary>regexp_match</primary>
3215 </indexterm>
3216 <function>regexp_match</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3217 <returnvalue>text[]</returnvalue>
3218 </para>
3219 <para>
3220 Returns substrings within the first match of the POSIX regular
3221 expression <parameter>pattern</parameter> to
3222 the <parameter>string</parameter>; see
3223 <xref linkend="functions-posix-regexp"/>.
3224 </para>
3225 <para>
3226 <literal>regexp_match('foobarbequebaz', '(bar)(beque)')</literal>
3227 <returnvalue>{bar,beque}</returnvalue>
3228 </para></entry>
3229 </row>
3231 <row>
3232 <entry role="func_table_entry"><para role="func_signature">
3233 <indexterm>
3234 <primary>regexp_matches</primary>
3235 </indexterm>
3236 <function>regexp_matches</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3237 <returnvalue>setof text[]</returnvalue>
3238 </para>
3239 <para>
3240 Returns substrings within the first match of the POSIX regular
3241 expression <parameter>pattern</parameter> to
3242 the <parameter>string</parameter>, or substrings within all
3243 such matches if the <literal>g</literal> flag is used;
3244 see <xref linkend="functions-posix-regexp"/>.
3245 </para>
3246 <para>
3247 <literal>regexp_matches('foobarbequebaz', 'ba.', 'g')</literal>
3248 <returnvalue></returnvalue>
3249 <programlisting>
3250 {bar}
3251 {baz}
3252 </programlisting>
3253 </para></entry>
3254 </row>
3256 <row>
3257 <entry role="func_table_entry"><para role="func_signature">
3258 <indexterm>
3259 <primary>regexp_replace</primary>
3260 </indexterm>
3261 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>
3262 [, <parameter>start</parameter> <type>integer</type> ]
3263 [, <parameter>flags</parameter> <type>text</type> ] )
3264 <returnvalue>text</returnvalue>
3265 </para>
3266 <para>
3267 Replaces the substring that is the first match to the POSIX
3268 regular expression <parameter>pattern</parameter>, or all such
3269 matches if the <literal>g</literal> flag is used; see
3270 <xref linkend="functions-posix-regexp"/>.
3271 </para>
3272 <para>
3273 <literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal>
3274 <returnvalue>ThM</returnvalue>
3275 </para></entry>
3276 </row>
3278 <row>
3279 <entry role="func_table_entry"><para role="func_signature">
3280 <function>regexp_replace</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type>,
3281 <parameter>start</parameter> <type>integer</type>,
3282 <parameter>N</parameter> <type>integer</type>
3283 [, <parameter>flags</parameter> <type>text</type> ] )
3284 <returnvalue>text</returnvalue>
3285 </para>
3286 <para>
3287 Replaces the substring that is the <parameter>N</parameter>'th
3288 match to the POSIX regular expression <parameter>pattern</parameter>,
3289 or all such matches if <parameter>N</parameter> is zero; see
3290 <xref linkend="functions-posix-regexp"/>.
3291 </para>
3292 <para>
3293 <literal>regexp_replace('Thomas', '.', 'X', 3, 2)</literal>
3294 <returnvalue>ThoXas</returnvalue>
3295 </para></entry>
3296 </row>
3298 <row>
3299 <entry role="func_table_entry"><para role="func_signature">
3300 <indexterm>
3301 <primary>regexp_split_to_array</primary>
3302 </indexterm>
3303 <function>regexp_split_to_array</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3304 <returnvalue>text[]</returnvalue>
3305 </para>
3306 <para>
3307 Splits <parameter>string</parameter> using a POSIX regular
3308 expression as the delimiter, producing an array of results; see
3309 <xref linkend="functions-posix-regexp"/>.
3310 </para>
3311 <para>
3312 <literal>regexp_split_to_array('hello world', '\s+')</literal>
3313 <returnvalue>{hello,world}</returnvalue>
3314 </para></entry>
3315 </row>
3317 <row>
3318 <entry role="func_table_entry"><para role="func_signature">
3319 <indexterm>
3320 <primary>regexp_split_to_table</primary>
3321 </indexterm>
3322 <function>regexp_split_to_table</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ] )
3323 <returnvalue>setof text</returnvalue>
3324 </para>
3325 <para>
3326 Splits <parameter>string</parameter> using a POSIX regular
3327 expression as the delimiter, producing a set of results; see
3328 <xref linkend="functions-posix-regexp"/>.
3329 </para>
3330 <para>
3331 <literal>regexp_split_to_table('hello world', '\s+')</literal>
3332 <returnvalue></returnvalue>
3333 <programlisting>
3334 hello
3335 world
3336 </programlisting>
3337 </para></entry>
3338 </row>
3340 <row>
3341 <entry role="func_table_entry"><para role="func_signature">
3342 <indexterm>
3343 <primary>regexp_substr</primary>
3344 </indexterm>
3345 <function>regexp_substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>
3346 [, <parameter>start</parameter> <type>integer</type>
3347 [, <parameter>N</parameter> <type>integer</type>
3348 [, <parameter>flags</parameter> <type>text</type>
3349 [, <parameter>subexpr</parameter> <type>integer</type> ] ] ] ] )
3350 <returnvalue>text</returnvalue>
3351 </para>
3352 <para>
3353 Returns the substring within <parameter>string</parameter> that
3354 matches the <parameter>N</parameter>'th occurrence of the POSIX
3355 regular expression <parameter>pattern</parameter>,
3356 or <literal>NULL</literal> if there is no such match; see
3357 <xref linkend="functions-posix-regexp"/>.
3358 </para>
3359 <para>
3360 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i')</literal>
3361 <returnvalue>CDEF</returnvalue>
3362 </para>
3363 <para>
3364 <literal>regexp_substr('ABCDEF', 'c(.)(..)', 1, 1, 'i', 2)</literal>
3365 <returnvalue>EF</returnvalue>
3366 </para></entry>
3367 </row>
3369 <row>
3370 <entry role="func_table_entry"><para role="func_signature">
3371 <indexterm>
3372 <primary>repeat</primary>
3373 </indexterm>
3374 <function>repeat</function> ( <parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>integer</type> )
3375 <returnvalue>text</returnvalue>
3376 </para>
3377 <para>
3378 Repeats <parameter>string</parameter> the specified
3379 <parameter>number</parameter> of times.
3380 </para>
3381 <para>
3382 <literal>repeat('Pg', 4)</literal>
3383 <returnvalue>PgPgPgPg</returnvalue>
3384 </para></entry>
3385 </row>
3387 <row>
3388 <entry role="func_table_entry"><para role="func_signature">
3389 <indexterm>
3390 <primary>replace</primary>
3391 </indexterm>
3392 <function>replace</function> ( <parameter>string</parameter> <type>text</type>,
3393 <parameter>from</parameter> <type>text</type>,
3394 <parameter>to</parameter> <type>text</type> )
3395 <returnvalue>text</returnvalue>
3396 </para>
3397 <para>
3398 Replaces all occurrences in <parameter>string</parameter> of
3399 substring <parameter>from</parameter> with
3400 substring <parameter>to</parameter>.
3401 </para>
3402 <para>
3403 <literal>replace('abcdefabcdef', 'cd', 'XX')</literal>
3404 <returnvalue>abXXefabXXef</returnvalue>
3405 </para></entry>
3406 </row>
3408 <row>
3409 <entry role="func_table_entry"><para role="func_signature">
3410 <indexterm>
3411 <primary>reverse</primary>
3412 </indexterm>
3413 <function>reverse</function> ( <type>text</type> )
3414 <returnvalue>text</returnvalue>
3415 </para>
3416 <para>
3417 Reverses the order of the characters in the string.
3418 </para>
3419 <para>
3420 <literal>reverse('abcde')</literal>
3421 <returnvalue>edcba</returnvalue>
3422 </para></entry>
3423 </row>
3425 <row>
3426 <entry role="func_table_entry"><para role="func_signature">
3427 <indexterm>
3428 <primary>right</primary>
3429 </indexterm>
3430 <function>right</function> ( <parameter>string</parameter> <type>text</type>,
3431 <parameter>n</parameter> <type>integer</type> )
3432 <returnvalue>text</returnvalue>
3433 </para>
3434 <para>
3435 Returns last <parameter>n</parameter> characters in the string,
3436 or when <parameter>n</parameter> is negative, returns all but
3437 first |<parameter>n</parameter>| characters.
3438 </para>
3439 <para>
3440 <literal>right('abcde', 2)</literal>
3441 <returnvalue>de</returnvalue>
3442 </para></entry>
3443 </row>
3445 <row>
3446 <entry role="func_table_entry"><para role="func_signature">
3447 <indexterm>
3448 <primary>rpad</primary>
3449 </indexterm>
3450 <function>rpad</function> ( <parameter>string</parameter> <type>text</type>,
3451 <parameter>length</parameter> <type>integer</type>
3452 <optional>, <parameter>fill</parameter> <type>text</type> </optional> )
3453 <returnvalue>text</returnvalue>
3454 </para>
3455 <para>
3456 Extends the <parameter>string</parameter> to length
3457 <parameter>length</parameter> by appending the characters
3458 <parameter>fill</parameter> (a space by default). If the
3459 <parameter>string</parameter> is already longer than
3460 <parameter>length</parameter> then it is truncated.
3461 </para>
3462 <para>
3463 <literal>rpad('hi', 5, 'xy')</literal>
3464 <returnvalue>hixyx</returnvalue>
3465 </para></entry>
3466 </row>
3468 <row>
3469 <entry role="func_table_entry"><para role="func_signature">
3470 <indexterm>
3471 <primary>rtrim</primary>
3472 </indexterm>
3473 <function>rtrim</function> ( <parameter>string</parameter> <type>text</type>
3474 <optional>, <parameter>characters</parameter> <type>text</type> </optional> )
3475 <returnvalue>text</returnvalue>
3476 </para>
3477 <para>
3478 Removes the longest string containing only characters in
3479 <parameter>characters</parameter> (a space by default) from the end of
3480 <parameter>string</parameter>.
3481 </para>
3482 <para>
3483 <literal>rtrim('testxxzx', 'xyz')</literal>
3484 <returnvalue>test</returnvalue>
3485 </para></entry>
3486 </row>
3488 <row>
3489 <entry role="func_table_entry"><para role="func_signature">
3490 <indexterm>
3491 <primary>split_part</primary>
3492 </indexterm>
3493 <function>split_part</function> ( <parameter>string</parameter> <type>text</type>,
3494 <parameter>delimiter</parameter> <type>text</type>,
3495 <parameter>n</parameter> <type>integer</type> )
3496 <returnvalue>text</returnvalue>
3497 </para>
3498 <para>
3499 Splits <parameter>string</parameter> at occurrences
3500 of <parameter>delimiter</parameter> and returns
3501 the <parameter>n</parameter>'th field (counting from one),
3502 or when <parameter>n</parameter> is negative, returns
3503 the |<parameter>n</parameter>|'th-from-last field.
3504 </para>
3505 <para>
3506 <literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal>
3507 <returnvalue>def</returnvalue>
3508 </para>
3509 <para>
3510 <literal>split_part('abc,def,ghi,jkl', ',', -2)</literal>
3511 <returnvalue>ghi</returnvalue>
3512 </para></entry>
3513 </row>
3515 <row>
3516 <entry role="func_table_entry"><para role="func_signature">
3517 <indexterm>
3518 <primary>starts_with</primary>
3519 </indexterm>
3520 <function>starts_with</function> ( <parameter>string</parameter> <type>text</type>, <parameter>prefix</parameter> <type>text</type> )
3521 <returnvalue>boolean</returnvalue>
3522 </para>
3523 <para>
3524 Returns true if <parameter>string</parameter> starts
3525 with <parameter>prefix</parameter>.
3526 </para>
3527 <para>
3528 <literal>starts_with('alphabet', 'alph')</literal>
3529 <returnvalue>t</returnvalue>
3530 </para></entry>
3531 </row>
3533 <row>
3534 <entry role="func_table_entry"><para role="func_signature">
3535 <indexterm id="function-string-to-array">
3536 <primary>string_to_array</primary>
3537 </indexterm>
3538 <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> )
3539 <returnvalue>text[]</returnvalue>
3540 </para>
3541 <para>
3542 Splits the <parameter>string</parameter> at occurrences
3543 of <parameter>delimiter</parameter> and forms the resulting fields
3544 into a <type>text</type> array.
3545 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3546 each character in the <parameter>string</parameter> will become a
3547 separate element in the array.
3548 If <parameter>delimiter</parameter> is an empty string, then
3549 the <parameter>string</parameter> is treated as a single field.
3550 If <parameter>null_string</parameter> is supplied and is
3551 not <literal>NULL</literal>, fields matching that string are
3552 replaced by <literal>NULL</literal>.
3553 See also <link linkend="function-array-to-string"><function>array_to_string</function></link>.
3554 </para>
3555 <para>
3556 <literal>string_to_array('xx~~yy~~zz', '~~', 'yy')</literal>
3557 <returnvalue>{xx,NULL,zz}</returnvalue>
3558 </para></entry>
3559 </row>
3561 <row>
3562 <entry role="func_table_entry"><para role="func_signature">
3563 <indexterm>
3564 <primary>string_to_table</primary>
3565 </indexterm>
3566 <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> )
3567 <returnvalue>setof text</returnvalue>
3568 </para>
3569 <para>
3570 Splits the <parameter>string</parameter> at occurrences
3571 of <parameter>delimiter</parameter> and returns the resulting fields
3572 as a set of <type>text</type> rows.
3573 If <parameter>delimiter</parameter> is <literal>NULL</literal>,
3574 each character in the <parameter>string</parameter> will become a
3575 separate row of the result.
3576 If <parameter>delimiter</parameter> is an empty string, then
3577 the <parameter>string</parameter> is treated as a single field.
3578 If <parameter>null_string</parameter> is supplied and is
3579 not <literal>NULL</literal>, fields matching that string are
3580 replaced by <literal>NULL</literal>.
3581 </para>
3582 <para>
3583 <literal>string_to_table('xx~^~yy~^~zz', '~^~', 'yy')</literal>
3584 <returnvalue></returnvalue>
3585 <programlisting>
3587 NULL
3589 </programlisting>
3590 </para></entry>
3591 </row>
3593 <row>
3594 <entry role="func_table_entry"><para role="func_signature">
3595 <indexterm>
3596 <primary>strpos</primary>
3597 </indexterm>
3598 <function>strpos</function> ( <parameter>string</parameter> <type>text</type>, <parameter>substring</parameter> <type>text</type> )
3599 <returnvalue>integer</returnvalue>
3600 </para>
3601 <para>
3602 Returns first starting index of the specified <parameter>substring</parameter>
3603 within <parameter>string</parameter>, or zero if it's not present.
3604 (Same as <literal>position(<parameter>substring</parameter> in
3605 <parameter>string</parameter>)</literal>, but note the reversed
3606 argument order.)
3607 </para>
3608 <para>
3609 <literal>strpos('high', 'ig')</literal>
3610 <returnvalue>2</returnvalue>
3611 </para></entry>
3612 </row>
3614 <row>
3615 <entry role="func_table_entry"><para role="func_signature">
3616 <indexterm>
3617 <primary>substr</primary>
3618 </indexterm>
3619 <function>substr</function> ( <parameter>string</parameter> <type>text</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
3620 <returnvalue>text</returnvalue>
3621 </para>
3622 <para>
3623 Extracts the substring of <parameter>string</parameter> starting at
3624 the <parameter>start</parameter>'th character,
3625 and extending for <parameter>count</parameter> characters if that is
3626 specified. (Same
3627 as <literal>substring(<parameter>string</parameter>
3628 from <parameter>start</parameter>
3629 for <parameter>count</parameter>)</literal>.)
3630 </para>
3631 <para>
3632 <literal>substr('alphabet', 3)</literal>
3633 <returnvalue>phabet</returnvalue>
3634 </para>
3635 <para>
3636 <literal>substr('alphabet', 3, 2)</literal>
3637 <returnvalue>ph</returnvalue>
3638 </para></entry>
3639 </row>
3641 <row>
3642 <entry role="func_table_entry"><para role="func_signature">
3643 <indexterm>
3644 <primary>to_ascii</primary>
3645 </indexterm>
3646 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type> )
3647 <returnvalue>text</returnvalue>
3648 </para>
3649 <para role="func_signature">
3650 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3651 <parameter>encoding</parameter> <type>name</type> )
3652 <returnvalue>text</returnvalue>
3653 </para>
3654 <para role="func_signature">
3655 <function>to_ascii</function> ( <parameter>string</parameter> <type>text</type>,
3656 <parameter>encoding</parameter> <type>integer</type> )
3657 <returnvalue>text</returnvalue>
3658 </para>
3659 <para>
3660 Converts <parameter>string</parameter> to <acronym>ASCII</acronym>
3661 from another encoding, which may be identified by name or number.
3662 If <parameter>encoding</parameter> is omitted the database encoding
3663 is assumed (which in practice is the only useful case).
3664 The conversion consists primarily of dropping accents.
3665 Conversion is only supported
3666 from <literal>LATIN1</literal>, <literal>LATIN2</literal>,
3667 <literal>LATIN9</literal>, and <literal>WIN1250</literal> encodings.
3668 (See the <xref linkend="unaccent"/> module for another, more flexible
3669 solution.)
3670 </para>
3671 <para>
3672 <literal>to_ascii('Kar&eacute;l')</literal>
3673 <returnvalue>Karel</returnvalue>
3674 </para></entry>
3675 </row>
3677 <row>
3678 <entry role="func_table_entry"><para role="func_signature">
3679 <indexterm>
3680 <primary>to_hex</primary>
3681 </indexterm>
3682 <function>to_hex</function> ( <type>integer</type> )
3683 <returnvalue>text</returnvalue>
3684 </para>
3685 <para role="func_signature">
3686 <function>to_hex</function> ( <type>bigint</type> )
3687 <returnvalue>text</returnvalue>
3688 </para>
3689 <para>
3690 Converts the number to its equivalent hexadecimal representation.
3691 </para>
3692 <para>
3693 <literal>to_hex(2147483647)</literal>
3694 <returnvalue>7fffffff</returnvalue>
3695 </para></entry>
3696 </row>
3698 <row>
3699 <entry role="func_table_entry"><para role="func_signature">
3700 <indexterm>
3701 <primary>translate</primary>
3702 </indexterm>
3703 <function>translate</function> ( <parameter>string</parameter> <type>text</type>,
3704 <parameter>from</parameter> <type>text</type>,
3705 <parameter>to</parameter> <type>text</type> )
3706 <returnvalue>text</returnvalue>
3707 </para>
3708 <para>
3709 Replaces each character in <parameter>string</parameter> that
3710 matches a character in the <parameter>from</parameter> set with the
3711 corresponding character in the <parameter>to</parameter>
3712 set. If <parameter>from</parameter> is longer than
3713 <parameter>to</parameter>, occurrences of the extra characters in
3714 <parameter>from</parameter> are deleted.
3715 </para>
3716 <para>
3717 <literal>translate('12345', '143', 'ax')</literal>
3718 <returnvalue>a2x5</returnvalue>
3719 </para></entry>
3720 </row>
3722 <row>
3723 <entry role="func_table_entry"><para role="func_signature">
3724 <indexterm>
3725 <primary>unistr</primary>
3726 </indexterm>
3727 <function>unistr</function> ( <type>text</type> )
3728 <returnvalue>text</returnvalue>
3729 </para>
3730 <para>
3731 Evaluate escaped Unicode characters in the argument. Unicode characters
3732 can be specified as
3733 <literal>\<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3734 digits), <literal>\+<replaceable>XXXXXX</replaceable></literal> (6
3735 hexadecimal digits),
3736 <literal>\u<replaceable>XXXX</replaceable></literal> (4 hexadecimal
3737 digits), or <literal>\U<replaceable>XXXXXXXX</replaceable></literal>
3738 (8 hexadecimal digits). To specify a backslash, write two
3739 backslashes. All other characters are taken literally.
3740 </para>
3742 <para>
3743 If the server encoding is not UTF-8, the Unicode code point identified
3744 by one of these escape sequences is converted to the actual server
3745 encoding; an error is reported if that's not possible.
3746 </para>
3748 <para>
3749 This function provides a (non-standard) alternative to string
3750 constants with Unicode escapes (see <xref
3751 linkend="sql-syntax-strings-uescape"/>).
3752 </para>
3754 <para>
3755 <literal>unistr('d\0061t\+000061')</literal>
3756 <returnvalue>data</returnvalue>
3757 </para>
3758 <para>
3759 <literal>unistr('d\u0061t\U00000061')</literal>
3760 <returnvalue>data</returnvalue>
3761 </para></entry>
3762 </row>
3764 </tbody>
3765 </tgroup>
3766 </table>
3768 <para>
3769 The <function>concat</function>, <function>concat_ws</function> and
3770 <function>format</function> functions are variadic, so it is possible to
3771 pass the values to be concatenated or formatted as an array marked with
3772 the <literal>VARIADIC</literal> keyword (see <xref
3773 linkend="xfunc-sql-variadic-functions"/>). The array's elements are
3774 treated as if they were separate ordinary arguments to the function.
3775 If the variadic array argument is NULL, <function>concat</function>
3776 and <function>concat_ws</function> return NULL, but
3777 <function>format</function> treats a NULL as a zero-element array.
3778 </para>
3780 <para>
3781 See also the aggregate function <function>string_agg</function> in
3782 <xref linkend="functions-aggregate"/>, and the functions for
3783 converting between strings and the <type>bytea</type> type in
3784 <xref linkend="functions-binarystring-conversions"/>.
3785 </para>
3787 <sect2 id="functions-string-format">
3788 <title><function>format</function></title>
3790 <indexterm>
3791 <primary>format</primary>
3792 </indexterm>
3794 <para>
3795 The function <function>format</function> produces output formatted according to
3796 a format string, in a style similar to the C function
3797 <function>sprintf</function>.
3798 </para>
3800 <para>
3801 <synopsis>
3802 <function>format</function>(<parameter>formatstr</parameter> <type>text</type> [, <parameter>formatarg</parameter> <type>"any"</type> [, ...] ])
3803 </synopsis>
3804 <parameter>formatstr</parameter> is a format string that specifies how the
3805 result should be formatted. Text in the format string is copied
3806 directly to the result, except where <firstterm>format specifiers</firstterm> are
3807 used. Format specifiers act as placeholders in the string, defining how
3808 subsequent function arguments should be formatted and inserted into the
3809 result. Each <parameter>formatarg</parameter> argument is converted to text
3810 according to the usual output rules for its data type, and then formatted
3811 and inserted into the result string according to the format specifier(s).
3812 </para>
3814 <para>
3815 Format specifiers are introduced by a <literal>%</literal> character and have
3816 the form
3817 <synopsis>
3818 %[<parameter>position</parameter>][<parameter>flags</parameter>][<parameter>width</parameter>]<parameter>type</parameter>
3819 </synopsis>
3820 where the component fields are:
3822 <variablelist>
3823 <varlistentry>
3824 <term><parameter>position</parameter> (optional)</term>
3825 <listitem>
3826 <para>
3827 A string of the form <literal><parameter>n</parameter>$</literal> where
3828 <parameter>n</parameter> is the index of the argument to print.
3829 Index 1 means the first argument after
3830 <parameter>formatstr</parameter>. If the <parameter>position</parameter> is
3831 omitted, the default is to use the next argument in sequence.
3832 </para>
3833 </listitem>
3834 </varlistentry>
3836 <varlistentry>
3837 <term><parameter>flags</parameter> (optional)</term>
3838 <listitem>
3839 <para>
3840 Additional options controlling how the format specifier's output is
3841 formatted. Currently the only supported flag is a minus sign
3842 (<literal>-</literal>) which will cause the format specifier's output to be
3843 left-justified. This has no effect unless the <parameter>width</parameter>
3844 field is also specified.
3845 </para>
3846 </listitem>
3847 </varlistentry>
3849 <varlistentry>
3850 <term><parameter>width</parameter> (optional)</term>
3851 <listitem>
3852 <para>
3853 Specifies the <emphasis>minimum</emphasis> number of characters to use to
3854 display the format specifier's output. The output is padded on the
3855 left or right (depending on the <literal>-</literal> flag) with spaces as
3856 needed to fill the width. A too-small width does not cause
3857 truncation of the output, but is simply ignored. The width may be
3858 specified using any of the following: a positive integer; an
3859 asterisk (<literal>*</literal>) to use the next function argument as the
3860 width; or a string of the form <literal>*<parameter>n</parameter>$</literal> to
3861 use the <parameter>n</parameter>th function argument as the width.
3862 </para>
3864 <para>
3865 If the width comes from a function argument, that argument is
3866 consumed before the argument that is used for the format specifier's
3867 value. If the width argument is negative, the result is left
3868 aligned (as if the <literal>-</literal> flag had been specified) within a
3869 field of length <function>abs</function>(<parameter>width</parameter>).
3870 </para>
3871 </listitem>
3872 </varlistentry>
3874 <varlistentry>
3875 <term><parameter>type</parameter> (required)</term>
3876 <listitem>
3877 <para>
3878 The type of format conversion to use to produce the format
3879 specifier's output. The following types are supported:
3880 <itemizedlist>
3881 <listitem>
3882 <para>
3883 <literal>s</literal> formats the argument value as a simple
3884 string. A null value is treated as an empty string.
3885 </para>
3886 </listitem>
3887 <listitem>
3888 <para>
3889 <literal>I</literal> treats the argument value as an SQL
3890 identifier, double-quoting it if necessary.
3891 It is an error for the value to be null (equivalent to
3892 <function>quote_ident</function>).
3893 </para>
3894 </listitem>
3895 <listitem>
3896 <para>
3897 <literal>L</literal> quotes the argument value as an SQL literal.
3898 A null value is displayed as the string <literal>NULL</literal>, without
3899 quotes (equivalent to <function>quote_nullable</function>).
3900 </para>
3901 </listitem>
3902 </itemizedlist>
3903 </para>
3904 </listitem>
3905 </varlistentry>
3906 </variablelist>
3907 </para>
3909 <para>
3910 In addition to the format specifiers described above, the special sequence
3911 <literal>%%</literal> may be used to output a literal <literal>%</literal> character.
3912 </para>
3914 <para>
3915 Here are some examples of the basic format conversions:
3917 <screen>
3918 SELECT format('Hello %s', 'World');
3919 <lineannotation>Result: </lineannotation><computeroutput>Hello World</computeroutput>
3921 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
3922 <lineannotation>Result: </lineannotation><computeroutput>Testing one, two, three, %</computeroutput>
3924 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
3925 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO "Foo bar" VALUES('O''Reilly')</computeroutput>
3927 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
3928 <lineannotation>Result: </lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')</computeroutput>
3929 </screen>
3930 </para>
3932 <para>
3933 Here are examples using <parameter>width</parameter> fields
3934 and the <literal>-</literal> flag:
3936 <screen>
3937 SELECT format('|%10s|', 'foo');
3938 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
3940 SELECT format('|%-10s|', 'foo');
3941 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
3943 SELECT format('|%*s|', 10, 'foo');
3944 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
3946 SELECT format('|%*s|', -10, 'foo');
3947 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
3949 SELECT format('|%-*s|', 10, 'foo');
3950 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
3952 SELECT format('|%-*s|', -10, 'foo');
3953 <lineannotation>Result: </lineannotation><computeroutput>|foo |</computeroutput>
3954 </screen>
3955 </para>
3957 <para>
3958 These examples show use of <parameter>position</parameter> fields:
3960 <screen>
3961 SELECT format('Testing %3$s, %2$s, %1$s', 'one', 'two', 'three');
3962 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, one</computeroutput>
3964 SELECT format('|%*2$s|', 'foo', 10, 'bar');
3965 <lineannotation>Result: </lineannotation><computeroutput>| bar|</computeroutput>
3967 SELECT format('|%1$*2$s|', 'foo', 10, 'bar');
3968 <lineannotation>Result: </lineannotation><computeroutput>| foo|</computeroutput>
3969 </screen>
3970 </para>
3972 <para>
3973 Unlike the standard C function <function>sprintf</function>,
3974 <productname>PostgreSQL</productname>'s <function>format</function> function allows format
3975 specifiers with and without <parameter>position</parameter> fields to be mixed
3976 in the same format string. A format specifier without a
3977 <parameter>position</parameter> field always uses the next argument after the
3978 last argument consumed.
3979 In addition, the <function>format</function> function does not require all
3980 function arguments to be used in the format string.
3981 For example:
3983 <screen>
3984 SELECT format('Testing %3$s, %2$s, %s', 'one', 'two', 'three');
3985 <lineannotation>Result: </lineannotation><computeroutput>Testing three, two, three</computeroutput>
3986 </screen>
3987 </para>
3989 <para>
3990 The <literal>%I</literal> and <literal>%L</literal> format specifiers are particularly
3991 useful for safely constructing dynamic SQL statements. See
3992 <xref linkend="plpgsql-quote-literal-example"/>.
3993 </para>
3994 </sect2>
3996 </sect1>
3999 <sect1 id="functions-binarystring">
4000 <title>Binary String Functions and Operators</title>
4002 <indexterm zone="functions-binarystring">
4003 <primary>binary data</primary>
4004 <secondary>functions</secondary>
4005 </indexterm>
4007 <para>
4008 This section describes functions and operators for examining and
4009 manipulating binary strings, that is values of type <type>bytea</type>.
4010 Many of these are equivalent, in purpose and syntax, to the
4011 text-string functions described in the previous section.
4012 </para>
4014 <para>
4015 <acronym>SQL</acronym> defines some string functions that use
4016 key words, rather than commas, to separate
4017 arguments. Details are in
4018 <xref linkend="functions-binarystring-sql"/>.
4019 <productname>PostgreSQL</productname> also provides versions of these functions
4020 that use the regular function invocation syntax
4021 (see <xref linkend="functions-binarystring-other"/>).
4022 </para>
4024 <table id="functions-binarystring-sql">
4025 <title><acronym>SQL</acronym> Binary String Functions and Operators</title>
4026 <tgroup cols="1">
4027 <thead>
4028 <row>
4029 <entry role="func_table_entry"><para role="func_signature">
4030 Function/Operator
4031 </para>
4032 <para>
4033 Description
4034 </para>
4035 <para>
4036 Example(s)
4037 </para></entry>
4038 </row>
4039 </thead>
4041 <tbody>
4042 <row>
4043 <entry role="func_table_entry"><para role="func_signature">
4044 <indexterm>
4045 <primary>binary string</primary>
4046 <secondary>concatenation</secondary>
4047 </indexterm>
4048 <type>bytea</type> <literal>||</literal> <type>bytea</type>
4049 <returnvalue>bytea</returnvalue>
4050 </para>
4051 <para>
4052 Concatenates the two binary strings.
4053 </para>
4054 <para>
4055 <literal>'\x123456'::bytea || '\x789a00bcde'::bytea</literal>
4056 <returnvalue>\x123456789a00bcde</returnvalue>
4057 </para></entry>
4058 </row>
4060 <row>
4061 <entry role="func_table_entry"><para role="func_signature">
4062 <indexterm>
4063 <primary>bit_length</primary>
4064 </indexterm>
4065 <function>bit_length</function> ( <type>bytea</type> )
4066 <returnvalue>integer</returnvalue>
4067 </para>
4068 <para>
4069 Returns number of bits in the binary string (8
4070 times the <function>octet_length</function>).
4071 </para>
4072 <para>
4073 <literal>bit_length('\x123456'::bytea)</literal>
4074 <returnvalue>24</returnvalue>
4075 </para></entry>
4076 </row>
4078 <row>
4079 <entry role="func_table_entry"><para role="func_signature">
4080 <indexterm>
4081 <primary>octet_length</primary>
4082 </indexterm>
4083 <function>octet_length</function> ( <type>bytea</type> )
4084 <returnvalue>integer</returnvalue>
4085 </para>
4086 <para>
4087 Returns number of bytes in the binary string.
4088 </para>
4089 <para>
4090 <literal>octet_length('\x123456'::bytea)</literal>
4091 <returnvalue>3</returnvalue>
4092 </para></entry>
4093 </row>
4095 <row>
4096 <entry role="func_table_entry"><para role="func_signature">
4097 <indexterm>
4098 <primary>overlay</primary>
4099 </indexterm>
4100 <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> )
4101 <returnvalue>bytea</returnvalue>
4102 </para>
4103 <para>
4104 Replaces the substring of <parameter>bytes</parameter> that starts at
4105 the <parameter>start</parameter>'th byte and extends
4106 for <parameter>count</parameter> bytes
4107 with <parameter>newsubstring</parameter>.
4108 If <parameter>count</parameter> is omitted, it defaults to the length
4109 of <parameter>newsubstring</parameter>.
4110 </para>
4111 <para>
4112 <literal>overlay('\x1234567890'::bytea placing '\002\003'::bytea from 2 for 3)</literal>
4113 <returnvalue>\x12020390</returnvalue>
4114 </para></entry>
4115 </row>
4117 <row>
4118 <entry role="func_table_entry"><para role="func_signature">
4119 <indexterm>
4120 <primary>position</primary>
4121 </indexterm>
4122 <function>position</function> ( <parameter>substring</parameter> <type>bytea</type> <literal>IN</literal> <parameter>bytes</parameter> <type>bytea</type> )
4123 <returnvalue>integer</returnvalue>
4124 </para>
4125 <para>
4126 Returns first starting index of the specified
4127 <parameter>substring</parameter> within
4128 <parameter>bytes</parameter>, or zero if it's not present.
4129 </para>
4130 <para>
4131 <literal>position('\x5678'::bytea in '\x1234567890'::bytea)</literal>
4132 <returnvalue>3</returnvalue>
4133 </para></entry>
4134 </row>
4136 <row>
4137 <entry role="func_table_entry"><para role="func_signature">
4138 <indexterm>
4139 <primary>substring</primary>
4140 </indexterm>
4141 <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> )
4142 <returnvalue>bytea</returnvalue>
4143 </para>
4144 <para>
4145 Extracts the substring of <parameter>bytes</parameter> starting at
4146 the <parameter>start</parameter>'th byte if that is specified,
4147 and stopping after <parameter>count</parameter> bytes if that is
4148 specified. Provide at least one of <parameter>start</parameter>
4149 and <parameter>count</parameter>.
4150 </para>
4151 <para>
4152 <literal>substring('\x1234567890'::bytea from 3 for 2)</literal>
4153 <returnvalue>\x5678</returnvalue>
4154 </para></entry>
4155 </row>
4157 <row>
4158 <entry role="func_table_entry"><para role="func_signature">
4159 <indexterm>
4160 <primary>trim</primary>
4161 </indexterm>
4162 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional>
4163 <parameter>bytesremoved</parameter> <type>bytea</type> <literal>FROM</literal>
4164 <parameter>bytes</parameter> <type>bytea</type> )
4165 <returnvalue>bytea</returnvalue>
4166 </para>
4167 <para>
4168 Removes the longest string containing only bytes appearing in
4169 <parameter>bytesremoved</parameter> from the start,
4170 end, or both ends (<literal>BOTH</literal> is the default)
4171 of <parameter>bytes</parameter>.
4172 </para>
4173 <para>
4174 <literal>trim('\x9012'::bytea from '\x1234567890'::bytea)</literal>
4175 <returnvalue>\x345678</returnvalue>
4176 </para></entry>
4177 </row>
4179 <row>
4180 <entry role="func_table_entry"><para role="func_signature">
4181 <function>trim</function> ( <optional> <literal>LEADING</literal> | <literal>TRAILING</literal> | <literal>BOTH</literal> </optional> <optional> <literal>FROM</literal> </optional>
4182 <parameter>bytes</parameter> <type>bytea</type>,
4183 <parameter>bytesremoved</parameter> <type>bytea</type> )
4184 <returnvalue>bytea</returnvalue>
4185 </para>
4186 <para>
4187 This is a non-standard syntax for <function>trim()</function>.
4188 </para>
4189 <para>
4190 <literal>trim(both from '\x1234567890'::bytea, '\x9012'::bytea)</literal>
4191 <returnvalue>\x345678</returnvalue>
4192 </para></entry>
4193 </row>
4194 </tbody>
4195 </tgroup>
4196 </table>
4198 <para>
4199 Additional binary string manipulation functions are available and
4200 are listed in <xref linkend="functions-binarystring-other"/>. Some
4201 of them are used internally to implement the
4202 <acronym>SQL</acronym>-standard string functions listed in <xref
4203 linkend="functions-binarystring-sql"/>.
4204 </para>
4206 <table id="functions-binarystring-other">
4207 <title>Other Binary String Functions</title>
4208 <tgroup cols="1">
4209 <thead>
4210 <row>
4211 <entry role="func_table_entry"><para role="func_signature">
4212 Function
4213 </para>
4214 <para>
4215 Description
4216 </para>
4217 <para>
4218 Example(s)
4219 </para></entry>
4220 </row>
4221 </thead>
4223 <tbody>
4224 <row>
4225 <entry role="func_table_entry"><para role="func_signature">
4226 <indexterm>
4227 <primary>bit_count</primary>
4228 </indexterm>
4229 <indexterm>
4230 <primary>popcount</primary>
4231 <see>bit_count</see>
4232 </indexterm>
4233 <function>bit_count</function> ( <parameter>bytes</parameter> <type>bytea</type> )
4234 <returnvalue>bigint</returnvalue>
4235 </para>
4236 <para>
4237 Returns the number of bits set in the binary string (also known as
4238 <quote>popcount</quote>).
4239 </para>
4240 <para>
4241 <literal>bit_count('\x1234567890'::bytea)</literal>
4242 <returnvalue>15</returnvalue>
4243 </para></entry>
4244 </row>
4246 <row>
4247 <entry role="func_table_entry"><para role="func_signature">
4248 <indexterm>
4249 <primary>btrim</primary>
4250 </indexterm>
4251 <function>btrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4252 <parameter>bytesremoved</parameter> <type>bytea</type> )
4253 <returnvalue>bytea</returnvalue>
4254 </para>
4255 <para>
4256 Removes the longest string containing only bytes appearing in
4257 <parameter>bytesremoved</parameter> from the start and end of
4258 <parameter>bytes</parameter>.
4259 </para>
4260 <para>
4261 <literal>btrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4262 <returnvalue>\x345678</returnvalue>
4263 </para></entry>
4264 </row>
4266 <row>
4267 <entry role="func_table_entry"><para role="func_signature">
4268 <indexterm>
4269 <primary>get_bit</primary>
4270 </indexterm>
4271 <function>get_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4272 <parameter>n</parameter> <type>bigint</type> )
4273 <returnvalue>integer</returnvalue>
4274 </para>
4275 <para>
4276 Extracts <link linkend="functions-zerobased-note">n'th</link> bit
4277 from binary string.
4278 </para>
4279 <para>
4280 <literal>get_bit('\x1234567890'::bytea, 30)</literal>
4281 <returnvalue>1</returnvalue>
4282 </para></entry>
4283 </row>
4285 <row>
4286 <entry role="func_table_entry"><para role="func_signature">
4287 <indexterm>
4288 <primary>get_byte</primary>
4289 </indexterm>
4290 <function>get_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4291 <parameter>n</parameter> <type>integer</type> )
4292 <returnvalue>integer</returnvalue>
4293 </para>
4294 <para>
4295 Extracts <link linkend="functions-zerobased-note">n'th</link> byte
4296 from binary string.
4297 </para>
4298 <para>
4299 <literal>get_byte('\x1234567890'::bytea, 4)</literal>
4300 <returnvalue>144</returnvalue>
4301 </para></entry>
4302 </row>
4304 <row>
4305 <entry role="func_table_entry"><para role="func_signature">
4306 <indexterm>
4307 <primary>length</primary>
4308 </indexterm>
4309 <indexterm>
4310 <primary>binary string</primary>
4311 <secondary>length</secondary>
4312 </indexterm>
4313 <indexterm>
4314 <primary>length</primary>
4315 <secondary sortas="binary string">of a binary string</secondary>
4316 <see>binary strings, length</see>
4317 </indexterm>
4318 <function>length</function> ( <type>bytea</type> )
4319 <returnvalue>integer</returnvalue>
4320 </para>
4321 <para>
4322 Returns the number of bytes in the binary string.
4323 </para>
4324 <para>
4325 <literal>length('\x1234567890'::bytea)</literal>
4326 <returnvalue>5</returnvalue>
4327 </para></entry>
4328 </row>
4330 <row>
4331 <entry role="func_table_entry"><para role="func_signature">
4332 <function>length</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4333 <parameter>encoding</parameter> <type>name</type> )
4334 <returnvalue>integer</returnvalue>
4335 </para>
4336 <para>
4337 Returns the number of characters in the binary string, assuming
4338 that it is text in the given <parameter>encoding</parameter>.
4339 </para>
4340 <para>
4341 <literal>length('jose'::bytea, 'UTF8')</literal>
4342 <returnvalue>4</returnvalue>
4343 </para></entry>
4344 </row>
4346 <row>
4347 <entry role="func_table_entry"><para role="func_signature">
4348 <indexterm>
4349 <primary>ltrim</primary>
4350 </indexterm>
4351 <function>ltrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4352 <parameter>bytesremoved</parameter> <type>bytea</type> )
4353 <returnvalue>bytea</returnvalue>
4354 </para>
4355 <para>
4356 Removes the longest string containing only bytes appearing in
4357 <parameter>bytesremoved</parameter> from the start of
4358 <parameter>bytes</parameter>.
4359 </para>
4360 <para>
4361 <literal>ltrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4362 <returnvalue>\x34567890</returnvalue>
4363 </para></entry>
4364 </row>
4366 <row>
4367 <entry role="func_table_entry"><para role="func_signature">
4368 <indexterm>
4369 <primary>md5</primary>
4370 </indexterm>
4371 <function>md5</function> ( <type>bytea</type> )
4372 <returnvalue>text</returnvalue>
4373 </para>
4374 <para>
4375 Computes the MD5 <link linkend="functions-hash-note">hash</link> of
4376 the binary string, with the result written in hexadecimal.
4377 </para>
4378 <para>
4379 <literal>md5('Th\000omas'::bytea)</literal>
4380 <returnvalue>8ab2d3c9689aaf18&zwsp;b4958c334c82d8b1</returnvalue>
4381 </para></entry>
4382 </row>
4384 <row>
4385 <entry role="func_table_entry"><para role="func_signature">
4386 <indexterm>
4387 <primary>rtrim</primary>
4388 </indexterm>
4389 <function>rtrim</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4390 <parameter>bytesremoved</parameter> <type>bytea</type> )
4391 <returnvalue>bytea</returnvalue>
4392 </para>
4393 <para>
4394 Removes the longest string containing only bytes appearing in
4395 <parameter>bytesremoved</parameter> from the end of
4396 <parameter>bytes</parameter>.
4397 </para>
4398 <para>
4399 <literal>rtrim('\x1234567890'::bytea, '\x9012'::bytea)</literal>
4400 <returnvalue>\x12345678</returnvalue>
4401 </para></entry>
4402 </row>
4404 <row>
4405 <entry role="func_table_entry"><para role="func_signature">
4406 <indexterm>
4407 <primary>set_bit</primary>
4408 </indexterm>
4409 <function>set_bit</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4410 <parameter>n</parameter> <type>bigint</type>,
4411 <parameter>newvalue</parameter> <type>integer</type> )
4412 <returnvalue>bytea</returnvalue>
4413 </para>
4414 <para>
4415 Sets <link linkend="functions-zerobased-note">n'th</link> bit in
4416 binary string to <parameter>newvalue</parameter>.
4417 </para>
4418 <para>
4419 <literal>set_bit('\x1234567890'::bytea, 30, 0)</literal>
4420 <returnvalue>\x1234563890</returnvalue>
4421 </para></entry>
4422 </row>
4424 <row>
4425 <entry role="func_table_entry"><para role="func_signature">
4426 <indexterm>
4427 <primary>set_byte</primary>
4428 </indexterm>
4429 <function>set_byte</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4430 <parameter>n</parameter> <type>integer</type>,
4431 <parameter>newvalue</parameter> <type>integer</type> )
4432 <returnvalue>bytea</returnvalue>
4433 </para>
4434 <para>
4435 Sets <link linkend="functions-zerobased-note">n'th</link> byte in
4436 binary string to <parameter>newvalue</parameter>.
4437 </para>
4438 <para>
4439 <literal>set_byte('\x1234567890'::bytea, 4, 64)</literal>
4440 <returnvalue>\x1234567840</returnvalue>
4441 </para></entry>
4442 </row>
4444 <row>
4445 <entry role="func_table_entry"><para role="func_signature">
4446 <indexterm>
4447 <primary>sha224</primary>
4448 </indexterm>
4449 <function>sha224</function> ( <type>bytea</type> )
4450 <returnvalue>bytea</returnvalue>
4451 </para>
4452 <para>
4453 Computes the SHA-224 <link linkend="functions-hash-note">hash</link>
4454 of the binary string.
4455 </para>
4456 <para>
4457 <literal>sha224('abc'::bytea)</literal>
4458 <returnvalue>\x23097d223405d8228642a477bda2&zwsp;55b32aadbce4bda0b3f7e36c9da7</returnvalue>
4459 </para></entry>
4460 </row>
4462 <row>
4463 <entry role="func_table_entry"><para role="func_signature">
4464 <indexterm>
4465 <primary>sha256</primary>
4466 </indexterm>
4467 <function>sha256</function> ( <type>bytea</type> )
4468 <returnvalue>bytea</returnvalue>
4469 </para>
4470 <para>
4471 Computes the SHA-256 <link linkend="functions-hash-note">hash</link>
4472 of the binary string.
4473 </para>
4474 <para>
4475 <literal>sha256('abc'::bytea)</literal>
4476 <returnvalue>\xba7816bf8f01cfea414140de5dae2223&zwsp;b00361a396177a9cb410ff61f20015ad</returnvalue>
4477 </para></entry>
4478 </row>
4480 <row>
4481 <entry role="func_table_entry"><para role="func_signature">
4482 <indexterm>
4483 <primary>sha384</primary>
4484 </indexterm>
4485 <function>sha384</function> ( <type>bytea</type> )
4486 <returnvalue>bytea</returnvalue>
4487 </para>
4488 <para>
4489 Computes the SHA-384 <link linkend="functions-hash-note">hash</link>
4490 of the binary string.
4491 </para>
4492 <para>
4493 <literal>sha384('abc'::bytea)</literal>
4494 <returnvalue>\xcb00753f45a35e8bb5a03d699ac65007&zwsp;272c32ab0eded1631a8b605a43ff5bed&zwsp;8086072ba1e7cc2358baeca134c825a7</returnvalue>
4495 </para></entry>
4496 </row>
4498 <row>
4499 <entry role="func_table_entry"><para role="func_signature">
4500 <indexterm>
4501 <primary>sha512</primary>
4502 </indexterm>
4503 <function>sha512</function> ( <type>bytea</type> )
4504 <returnvalue>bytea</returnvalue>
4505 </para>
4506 <para>
4507 Computes the SHA-512 <link linkend="functions-hash-note">hash</link>
4508 of the binary string.
4509 </para>
4510 <para>
4511 <literal>sha512('abc'::bytea)</literal>
4512 <returnvalue>\xddaf35a193617abacc417349ae204131&zwsp;12e6fa4e89a97ea20a9eeee64b55d39a&zwsp;2192992a274fc1a836ba3c23a3feebbd&zwsp;454d4423643ce80e2a9ac94fa54ca49f</returnvalue>
4513 </para></entry>
4514 </row>
4516 <row>
4517 <entry role="func_table_entry"><para role="func_signature">
4518 <indexterm>
4519 <primary>substr</primary>
4520 </indexterm>
4521 <function>substr</function> ( <parameter>bytes</parameter> <type>bytea</type>, <parameter>start</parameter> <type>integer</type> <optional>, <parameter>count</parameter> <type>integer</type> </optional> )
4522 <returnvalue>bytea</returnvalue>
4523 </para>
4524 <para>
4525 Extracts the substring of <parameter>bytes</parameter> starting at
4526 the <parameter>start</parameter>'th byte,
4527 and extending for <parameter>count</parameter> bytes if that is
4528 specified. (Same
4529 as <literal>substring(<parameter>bytes</parameter>
4530 from <parameter>start</parameter>
4531 for <parameter>count</parameter>)</literal>.)
4532 </para>
4533 <para>
4534 <literal>substr('\x1234567890'::bytea, 3, 2)</literal>
4535 <returnvalue>\x5678</returnvalue>
4536 </para></entry>
4537 </row>
4538 </tbody>
4539 </tgroup>
4540 </table>
4542 <para id="functions-zerobased-note">
4543 Functions <function>get_byte</function> and <function>set_byte</function>
4544 number the first byte of a binary string as byte 0.
4545 Functions <function>get_bit</function> and <function>set_bit</function>
4546 number bits from the right within each byte; for example bit 0 is the least
4547 significant bit of the first byte, and bit 15 is the most significant bit
4548 of the second byte.
4549 </para>
4551 <para id="functions-hash-note">
4552 For historical reasons, the function <function>md5</function>
4553 returns a hex-encoded value of type <type>text</type> whereas the SHA-2
4554 functions return type <type>bytea</type>. Use the functions
4555 <link linkend="function-encode"><function>encode</function></link>
4556 and <link linkend="function-decode"><function>decode</function></link> to
4557 convert between the two. For example write <literal>encode(sha256('abc'),
4558 'hex')</literal> to get a hex-encoded text representation,
4559 or <literal>decode(md5('abc'), 'hex')</literal> to get
4560 a <type>bytea</type> value.
4561 </para>
4563 <para>
4564 <indexterm>
4565 <primary>character string</primary>
4566 <secondary>converting to binary string</secondary>
4567 </indexterm>
4568 <indexterm>
4569 <primary>binary string</primary>
4570 <secondary>converting to character string</secondary>
4571 </indexterm>
4572 Functions for converting strings between different character sets
4573 (encodings), and for representing arbitrary binary data in textual
4574 form, are shown in
4575 <xref linkend="functions-binarystring-conversions"/>. For these
4576 functions, an argument or result of type <type>text</type> is expressed
4577 in the database's default encoding, while arguments or results of
4578 type <type>bytea</type> are in an encoding named by another argument.
4579 </para>
4581 <table id="functions-binarystring-conversions">
4582 <title>Text/Binary String Conversion Functions</title>
4583 <tgroup cols="1">
4584 <thead>
4585 <row>
4586 <entry role="func_table_entry"><para role="func_signature">
4587 Function
4588 </para>
4589 <para>
4590 Description
4591 </para>
4592 <para>
4593 Example(s)
4594 </para></entry>
4595 </row>
4596 </thead>
4598 <tbody>
4599 <row>
4600 <entry role="func_table_entry"><para role="func_signature">
4601 <indexterm>
4602 <primary>convert</primary>
4603 </indexterm>
4604 <function>convert</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4605 <parameter>src_encoding</parameter> <type>name</type>,
4606 <parameter>dest_encoding</parameter> <type>name</type> )
4607 <returnvalue>bytea</returnvalue>
4608 </para>
4609 <para>
4610 Converts a binary string representing text in
4611 encoding <parameter>src_encoding</parameter>
4612 to a binary string in encoding <parameter>dest_encoding</parameter>
4613 (see <xref linkend="multibyte-conversions-supported"/> for
4614 available conversions).
4615 </para>
4616 <para>
4617 <literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal>
4618 <returnvalue>\x746578745f696e5f75746638</returnvalue>
4619 </para></entry>
4620 </row>
4622 <row>
4623 <entry role="func_table_entry"><para role="func_signature">
4624 <indexterm>
4625 <primary>convert_from</primary>
4626 </indexterm>
4627 <function>convert_from</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4628 <parameter>src_encoding</parameter> <type>name</type> )
4629 <returnvalue>text</returnvalue>
4630 </para>
4631 <para>
4632 Converts a binary string representing text in
4633 encoding <parameter>src_encoding</parameter>
4634 to <type>text</type> in the database encoding
4635 (see <xref linkend="multibyte-conversions-supported"/> for
4636 available conversions).
4637 </para>
4638 <para>
4639 <literal>convert_from('text_in_utf8', 'UTF8')</literal>
4640 <returnvalue>text_in_utf8</returnvalue>
4641 </para></entry>
4642 </row>
4644 <row>
4645 <entry role="func_table_entry"><para role="func_signature">
4646 <indexterm>
4647 <primary>convert_to</primary>
4648 </indexterm>
4649 <function>convert_to</function> ( <parameter>string</parameter> <type>text</type>,
4650 <parameter>dest_encoding</parameter> <type>name</type> )
4651 <returnvalue>bytea</returnvalue>
4652 </para>
4653 <para>
4654 Converts a <type>text</type> string (in the database encoding) to a
4655 binary string encoded in encoding <parameter>dest_encoding</parameter>
4656 (see <xref linkend="multibyte-conversions-supported"/> for
4657 available conversions).
4658 </para>
4659 <para>
4660 <literal>convert_to('some_text', 'UTF8')</literal>
4661 <returnvalue>\x736f6d655f74657874</returnvalue>
4662 </para></entry>
4663 </row>
4665 <row>
4666 <entry role="func_table_entry"><para role="func_signature">
4667 <indexterm id="function-encode">
4668 <primary>encode</primary>
4669 </indexterm>
4670 <function>encode</function> ( <parameter>bytes</parameter> <type>bytea</type>,
4671 <parameter>format</parameter> <type>text</type> )
4672 <returnvalue>text</returnvalue>
4673 </para>
4674 <para>
4675 Encodes binary data into a textual representation; supported
4676 <parameter>format</parameter> values are:
4677 <link linkend="encode-format-base64"><literal>base64</literal></link>,
4678 <link linkend="encode-format-escape"><literal>escape</literal></link>,
4679 <link linkend="encode-format-hex"><literal>hex</literal></link>.
4680 </para>
4681 <para>
4682 <literal>encode('123\000\001', 'base64')</literal>
4683 <returnvalue>MTIzAAE=</returnvalue>
4684 </para></entry>
4685 </row>
4687 <row>
4688 <entry role="func_table_entry"><para role="func_signature">
4689 <indexterm id="function-decode">
4690 <primary>decode</primary>
4691 </indexterm>
4692 <function>decode</function> ( <parameter>string</parameter> <type>text</type>,
4693 <parameter>format</parameter> <type>text</type> )
4694 <returnvalue>bytea</returnvalue>
4695 </para>
4696 <para>
4697 Decodes binary data from a textual representation; supported
4698 <parameter>format</parameter> values are the same as
4699 for <function>encode</function>.
4700 </para>
4701 <para>
4702 <literal>decode('MTIzAAE=', 'base64')</literal>
4703 <returnvalue>\x3132330001</returnvalue>
4704 </para></entry>
4705 </row>
4706 </tbody>
4707 </tgroup>
4708 </table>
4710 <para>
4711 The <function>encode</function> and <function>decode</function>
4712 functions support the following textual formats:
4714 <variablelist>
4715 <varlistentry id="encode-format-base64">
4716 <term>base64
4717 <indexterm>
4718 <primary>base64 format</primary>
4719 </indexterm></term>
4720 <listitem>
4721 <para>
4722 The <literal>base64</literal> format is that
4723 of <ulink url="https://tools.ietf.org/html/rfc2045#section-6.8">RFC
4724 2045 Section 6.8</ulink>. As per the <acronym>RFC</acronym>, encoded lines are
4725 broken at 76 characters. However instead of the MIME CRLF
4726 end-of-line marker, only a newline is used for end-of-line.
4727 The <function>decode</function> function ignores carriage-return,
4728 newline, space, and tab characters. Otherwise, an error is
4729 raised when <function>decode</function> is supplied invalid
4730 base64 data &mdash; including when trailing padding is incorrect.
4731 </para>
4732 </listitem>
4733 </varlistentry>
4735 <varlistentry id="encode-format-escape">
4736 <term>escape
4737 <indexterm>
4738 <primary>escape format</primary>
4739 </indexterm></term>
4740 <listitem>
4741 <para>
4742 The <literal>escape</literal> format converts zero bytes and
4743 bytes with the high bit set into octal escape sequences
4744 (<literal>\</literal><replaceable>nnn</replaceable>), and it doubles
4745 backslashes. Other byte values are represented literally.
4746 The <function>decode</function> function will raise an error if a
4747 backslash is not followed by either a second backslash or three
4748 octal digits; it accepts other byte values unchanged.
4749 </para>
4750 </listitem>
4751 </varlistentry>
4753 <varlistentry id="encode-format-hex">
4754 <term>hex
4755 <indexterm>
4756 <primary>hex format</primary>
4757 </indexterm></term>
4758 <listitem>
4759 <para>
4760 The <literal>hex</literal> format represents each 4 bits of
4761 data as one hexadecimal digit, <literal>0</literal>
4762 through <literal>f</literal>, writing the higher-order digit of
4763 each byte first. The <function>encode</function> function outputs
4764 the <literal>a</literal>-<literal>f</literal> hex digits in lower
4765 case. Because the smallest unit of data is 8 bits, there are
4766 always an even number of characters returned
4767 by <function>encode</function>.
4768 The <function>decode</function> function
4769 accepts the <literal>a</literal>-<literal>f</literal> characters in
4770 either upper or lower case. An error is raised
4771 when <function>decode</function> is given invalid hex data
4772 &mdash; including when given an odd number of characters.
4773 </para>
4774 </listitem>
4775 </varlistentry>
4776 </variablelist>
4777 </para>
4779 <para>
4780 See also the aggregate function <function>string_agg</function> in
4781 <xref linkend="functions-aggregate"/> and the large object functions
4782 in <xref linkend="lo-funcs"/>.
4783 </para>
4784 </sect1>
4787 <sect1 id="functions-bitstring">
4788 <title>Bit String Functions and Operators</title>
4790 <indexterm zone="functions-bitstring">
4791 <primary>bit strings</primary>
4792 <secondary>functions</secondary>
4793 </indexterm>
4795 <para>
4796 This section describes functions and operators for examining and
4797 manipulating bit strings, that is values of the types
4798 <type>bit</type> and <type>bit varying</type>. (While only
4799 type <type>bit</type> is mentioned in these tables, values of
4800 type <type>bit varying</type> can be used interchangeably.)
4801 Bit strings support the usual comparison operators shown in
4802 <xref linkend="functions-comparison-op-table"/>, as well as the
4803 operators shown in <xref linkend="functions-bit-string-op-table"/>.
4804 </para>
4806 <table id="functions-bit-string-op-table">
4807 <title>Bit String Operators</title>
4808 <tgroup cols="1">
4809 <thead>
4810 <row>
4811 <entry role="func_table_entry"><para role="func_signature">
4812 Operator
4813 </para>
4814 <para>
4815 Description
4816 </para>
4817 <para>
4818 Example(s)
4819 </para></entry>
4820 </row>
4821 </thead>
4823 <tbody>
4824 <row>
4825 <entry role="func_table_entry"><para role="func_signature">
4826 <type>bit</type> <literal>||</literal> <type>bit</type>
4827 <returnvalue>bit</returnvalue>
4828 </para>
4829 <para>
4830 Concatenation
4831 </para>
4832 <para>
4833 <literal>B'10001' || B'011'</literal>
4834 <returnvalue>10001011</returnvalue>
4835 </para></entry>
4836 </row>
4838 <row>
4839 <entry role="func_table_entry"><para role="func_signature">
4840 <type>bit</type> <literal>&amp;</literal> <type>bit</type>
4841 <returnvalue>bit</returnvalue>
4842 </para>
4843 <para>
4844 Bitwise AND (inputs must be of equal length)
4845 </para>
4846 <para>
4847 <literal>B'10001' &amp; B'01101'</literal>
4848 <returnvalue>00001</returnvalue>
4849 </para></entry>
4850 </row>
4852 <row>
4853 <entry role="func_table_entry"><para role="func_signature">
4854 <type>bit</type> <literal>|</literal> <type>bit</type>
4855 <returnvalue>bit</returnvalue>
4856 </para>
4857 <para>
4858 Bitwise OR (inputs must be of equal length)
4859 </para>
4860 <para>
4861 <literal>B'10001' | B'01101'</literal>
4862 <returnvalue>11101</returnvalue>
4863 </para></entry>
4864 </row>
4866 <row>
4867 <entry role="func_table_entry"><para role="func_signature">
4868 <type>bit</type> <literal>#</literal> <type>bit</type>
4869 <returnvalue>bit</returnvalue>
4870 </para>
4871 <para>
4872 Bitwise exclusive OR (inputs must be of equal length)
4873 </para>
4874 <para>
4875 <literal>B'10001' # B'01101'</literal>
4876 <returnvalue>11100</returnvalue>
4877 </para></entry>
4878 </row>
4880 <row>
4881 <entry role="func_table_entry"><para role="func_signature">
4882 <literal>~</literal> <type>bit</type>
4883 <returnvalue>bit</returnvalue>
4884 </para>
4885 <para>
4886 Bitwise NOT
4887 </para>
4888 <para>
4889 <literal>~ B'10001'</literal>
4890 <returnvalue>01110</returnvalue>
4891 </para></entry>
4892 </row>
4894 <row>
4895 <entry role="func_table_entry"><para role="func_signature">
4896 <type>bit</type> <literal>&lt;&lt;</literal> <type>integer</type>
4897 <returnvalue>bit</returnvalue>
4898 </para>
4899 <para>
4900 Bitwise shift left
4901 (string length is preserved)
4902 </para>
4903 <para>
4904 <literal>B'10001' &lt;&lt; 3</literal>
4905 <returnvalue>01000</returnvalue>
4906 </para></entry>
4907 </row>
4909 <row>
4910 <entry role="func_table_entry"><para role="func_signature">
4911 <type>bit</type> <literal>&gt;&gt;</literal> <type>integer</type>
4912 <returnvalue>bit</returnvalue>
4913 </para>
4914 <para>
4915 Bitwise shift right
4916 (string length is preserved)
4917 </para>
4918 <para>
4919 <literal>B'10001' &gt;&gt; 2</literal>
4920 <returnvalue>00100</returnvalue>
4921 </para></entry>
4922 </row>
4923 </tbody>
4924 </tgroup>
4925 </table>
4927 <para>
4928 Some of the functions available for binary strings are also available
4929 for bit strings, as shown in <xref linkend="functions-bit-string-table"/>.
4930 </para>
4932 <table id="functions-bit-string-table">
4933 <title>Bit String Functions</title>
4934 <tgroup cols="1">
4935 <thead>
4936 <row>
4937 <entry role="func_table_entry"><para role="func_signature">
4938 Function
4939 </para>
4940 <para>
4941 Description
4942 </para>
4943 <para>
4944 Example(s)
4945 </para></entry>
4946 </row>
4947 </thead>
4949 <tbody>
4950 <row>
4951 <entry role="func_table_entry"><para role="func_signature">
4952 <indexterm>
4953 <primary>bit_count</primary>
4954 </indexterm>
4955 <function>bit_count</function> ( <type>bit</type> )
4956 <returnvalue>bigint</returnvalue>
4957 </para>
4958 <para>
4959 Returns the number of bits set in the bit string (also known as
4960 <quote>popcount</quote>).
4961 </para>
4962 <para>
4963 <literal>bit_count(B'10111')</literal>
4964 <returnvalue>4</returnvalue>
4965 </para></entry>
4966 </row>
4968 <row>
4969 <entry role="func_table_entry"><para role="func_signature">
4970 <indexterm>
4971 <primary>bit_length</primary>
4972 </indexterm>
4973 <function>bit_length</function> ( <type>bit</type> )
4974 <returnvalue>integer</returnvalue>
4975 </para>
4976 <para>
4977 Returns number of bits in the bit string.
4978 </para>
4979 <para>
4980 <literal>bit_length(B'10111')</literal>
4981 <returnvalue>5</returnvalue>
4982 </para></entry>
4983 </row>
4985 <row>
4986 <entry role="func_table_entry"><para role="func_signature">
4987 <indexterm>
4988 <primary>length</primary>
4989 </indexterm>
4990 <indexterm>
4991 <primary>bit string</primary>
4992 <secondary>length</secondary>
4993 </indexterm>
4994 <function>length</function> ( <type>bit</type> )
4995 <returnvalue>integer</returnvalue>
4996 </para>
4997 <para>
4998 Returns number of bits in the bit string.
4999 </para>
5000 <para>
5001 <literal>length(B'10111')</literal>
5002 <returnvalue>5</returnvalue>
5003 </para></entry>
5004 </row>
5006 <row>
5007 <entry role="func_table_entry"><para role="func_signature">
5008 <indexterm>
5009 <primary>octet_length</primary>
5010 </indexterm>
5011 <function>octet_length</function> ( <type>bit</type> )
5012 <returnvalue>integer</returnvalue>
5013 </para>
5014 <para>
5015 Returns number of bytes in the bit string.
5016 </para>
5017 <para>
5018 <literal>octet_length(B'1011111011')</literal>
5019 <returnvalue>2</returnvalue>
5020 </para></entry>
5021 </row>
5023 <row>
5024 <entry role="func_table_entry"><para role="func_signature">
5025 <indexterm>
5026 <primary>overlay</primary>
5027 </indexterm>
5028 <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> )
5029 <returnvalue>bit</returnvalue>
5030 </para>
5031 <para>
5032 Replaces the substring of <parameter>bits</parameter> that starts at
5033 the <parameter>start</parameter>'th bit and extends
5034 for <parameter>count</parameter> bits
5035 with <parameter>newsubstring</parameter>.
5036 If <parameter>count</parameter> is omitted, it defaults to the length
5037 of <parameter>newsubstring</parameter>.
5038 </para>
5039 <para>
5040 <literal>overlay(B'01010101010101010' placing B'11111' from 2 for 3)</literal>
5041 <returnvalue>0111110101010101010</returnvalue>
5042 </para></entry>
5043 </row>
5045 <row>
5046 <entry role="func_table_entry"><para role="func_signature">
5047 <indexterm>
5048 <primary>position</primary>
5049 </indexterm>
5050 <function>position</function> ( <parameter>substring</parameter> <type>bit</type> <literal>IN</literal> <parameter>bits</parameter> <type>bit</type> )
5051 <returnvalue>integer</returnvalue>
5052 </para>
5053 <para>
5054 Returns first starting index of the specified <parameter>substring</parameter>
5055 within <parameter>bits</parameter>, or zero if it's not present.
5056 </para>
5057 <para>
5058 <literal>position(B'010' in B'000001101011')</literal>
5059 <returnvalue>8</returnvalue>
5060 </para></entry>
5061 </row>
5063 <row>
5064 <entry role="func_table_entry"><para role="func_signature">
5065 <indexterm>
5066 <primary>substring</primary>
5067 </indexterm>
5068 <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> )
5069 <returnvalue>bit</returnvalue>
5070 </para>
5071 <para>
5072 Extracts the substring of <parameter>bits</parameter> starting at
5073 the <parameter>start</parameter>'th bit if that is specified,
5074 and stopping after <parameter>count</parameter> bits if that is
5075 specified. Provide at least one of <parameter>start</parameter>
5076 and <parameter>count</parameter>.
5077 </para>
5078 <para>
5079 <literal>substring(B'110010111111' from 3 for 2)</literal>
5080 <returnvalue>00</returnvalue>
5081 </para></entry>
5082 </row>
5084 <row>
5085 <entry role="func_table_entry"><para role="func_signature">
5086 <indexterm>
5087 <primary>get_bit</primary>
5088 </indexterm>
5089 <function>get_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5090 <parameter>n</parameter> <type>integer</type> )
5091 <returnvalue>integer</returnvalue>
5092 </para>
5093 <para>
5094 Extracts <parameter>n</parameter>'th bit
5095 from bit string; the first (leftmost) bit is bit 0.
5096 </para>
5097 <para>
5098 <literal>get_bit(B'101010101010101010', 6)</literal>
5099 <returnvalue>1</returnvalue>
5100 </para></entry>
5101 </row>
5103 <row>
5104 <entry role="func_table_entry"><para role="func_signature">
5105 <indexterm>
5106 <primary>set_bit</primary>
5107 </indexterm>
5108 <function>set_bit</function> ( <parameter>bits</parameter> <type>bit</type>,
5109 <parameter>n</parameter> <type>integer</type>,
5110 <parameter>newvalue</parameter> <type>integer</type> )
5111 <returnvalue>bit</returnvalue>
5112 </para>
5113 <para>
5114 Sets <parameter>n</parameter>'th bit in
5115 bit string to <parameter>newvalue</parameter>;
5116 the first (leftmost) bit is bit 0.
5117 </para>
5118 <para>
5119 <literal>set_bit(B'101010101010101010', 6, 0)</literal>
5120 <returnvalue>101010001010101010</returnvalue>
5121 </para></entry>
5122 </row>
5123 </tbody>
5124 </tgroup>
5125 </table>
5127 <para>
5128 In addition, it is possible to cast integral values to and from type
5129 <type>bit</type>.
5130 Casting an integer to <type>bit(n)</type> copies the rightmost
5131 <literal>n</literal> bits. Casting an integer to a bit string width wider
5132 than the integer itself will sign-extend on the left.
5133 Some examples:
5134 <programlisting>
5135 44::bit(10) <lineannotation>0000101100</lineannotation>
5136 44::bit(3) <lineannotation>100</lineannotation>
5137 cast(-44 as bit(12)) <lineannotation>111111010100</lineannotation>
5138 '1110'::bit(4)::integer <lineannotation>14</lineannotation>
5139 </programlisting>
5140 Note that casting to just <quote>bit</quote> means casting to
5141 <literal>bit(1)</literal>, and so will deliver only the least significant
5142 bit of the integer.
5143 </para>
5144 </sect1>
5147 <sect1 id="functions-matching">
5148 <title>Pattern Matching</title>
5150 <indexterm zone="functions-matching">
5151 <primary>pattern matching</primary>
5152 </indexterm>
5154 <para>
5155 There are three separate approaches to pattern matching provided
5156 by <productname>PostgreSQL</productname>: the traditional
5157 <acronym>SQL</acronym> <function>LIKE</function> operator, the
5158 more recent <function>SIMILAR TO</function> operator (added in
5159 SQL:1999), and <acronym>POSIX</acronym>-style regular
5160 expressions. Aside from the basic <quote>does this string match
5161 this pattern?</quote> operators, functions are available to extract
5162 or replace matching substrings and to split a string at matching
5163 locations.
5164 </para>
5166 <tip>
5167 <para>
5168 If you have pattern matching needs that go beyond this,
5169 consider writing a user-defined function in Perl or Tcl.
5170 </para>
5171 </tip>
5173 <caution>
5174 <para>
5175 While most regular-expression searches can be executed very quickly,
5176 regular expressions can be contrived that take arbitrary amounts of
5177 time and memory to process. Be wary of accepting regular-expression
5178 search patterns from hostile sources. If you must do so, it is
5179 advisable to impose a statement timeout.
5180 </para>
5182 <para>
5183 Searches using <function>SIMILAR TO</function> patterns have the same
5184 security hazards, since <function>SIMILAR TO</function> provides many
5185 of the same capabilities as <acronym>POSIX</acronym>-style regular
5186 expressions.
5187 </para>
5189 <para>
5190 <function>LIKE</function> searches, being much simpler than the other
5191 two options, are safer to use with possibly-hostile pattern sources.
5192 </para>
5193 </caution>
5195 <para>
5196 The pattern matching operators of all three kinds do not support
5197 nondeterministic collations. If required, apply a different collation to
5198 the expression to work around this limitation.
5199 </para>
5201 <sect2 id="functions-like">
5202 <title><function>LIKE</function></title>
5204 <indexterm>
5205 <primary>LIKE</primary>
5206 </indexterm>
5208 <synopsis>
5209 <replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5210 <replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5211 </synopsis>
5213 <para>
5214 The <function>LIKE</function> expression returns true if the
5215 <replaceable>string</replaceable> matches the supplied
5216 <replaceable>pattern</replaceable>. (As
5217 expected, the <function>NOT LIKE</function> expression returns
5218 false if <function>LIKE</function> returns true, and vice versa.
5219 An equivalent expression is
5220 <literal>NOT (<replaceable>string</replaceable> LIKE
5221 <replaceable>pattern</replaceable>)</literal>.)
5222 </para>
5224 <para>
5225 If <replaceable>pattern</replaceable> does not contain percent
5226 signs or underscores, then the pattern only represents the string
5227 itself; in that case <function>LIKE</function> acts like the
5228 equals operator. An underscore (<literal>_</literal>) in
5229 <replaceable>pattern</replaceable> stands for (matches) any single
5230 character; a percent sign (<literal>%</literal>) matches any sequence
5231 of zero or more characters.
5232 </para>
5234 <para>
5235 Some examples:
5236 <programlisting>
5237 'abc' LIKE 'abc' <lineannotation>true</lineannotation>
5238 'abc' LIKE 'a%' <lineannotation>true</lineannotation>
5239 'abc' LIKE '_b_' <lineannotation>true</lineannotation>
5240 'abc' LIKE 'c' <lineannotation>false</lineannotation>
5241 </programlisting>
5242 </para>
5244 <para>
5245 <function>LIKE</function> pattern matching always covers the entire
5246 string. Therefore, if it's desired to match a sequence anywhere within
5247 a string, the pattern must start and end with a percent sign.
5248 </para>
5250 <para>
5251 To match a literal underscore or percent sign without matching
5252 other characters, the respective character in
5253 <replaceable>pattern</replaceable> must be
5254 preceded by the escape character. The default escape
5255 character is the backslash but a different one can be selected by
5256 using the <literal>ESCAPE</literal> clause. To match the escape
5257 character itself, write two escape characters.
5258 </para>
5260 <note>
5261 <para>
5262 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
5263 any backslashes you write in literal string constants will need to be
5264 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
5265 </para>
5266 </note>
5268 <para>
5269 It's also possible to select no escape character by writing
5270 <literal>ESCAPE ''</literal>. This effectively disables the
5271 escape mechanism, which makes it impossible to turn off the
5272 special meaning of underscore and percent signs in the pattern.
5273 </para>
5275 <para>
5276 According to the SQL standard, omitting <literal>ESCAPE</literal>
5277 means there is no escape character (rather than defaulting to a
5278 backslash), and a zero-length <literal>ESCAPE</literal> value is
5279 disallowed. <productname>PostgreSQL</productname>'s behavior in
5280 this regard is therefore slightly nonstandard.
5281 </para>
5283 <para>
5284 The key word <token>ILIKE</token> can be used instead of
5285 <token>LIKE</token> to make the match case-insensitive according
5286 to the active locale. This is not in the <acronym>SQL</acronym> standard but is a
5287 <productname>PostgreSQL</productname> extension.
5288 </para>
5290 <para>
5291 The operator <literal>~~</literal> is equivalent to
5292 <function>LIKE</function>, and <literal>~~*</literal> corresponds to
5293 <function>ILIKE</function>. There are also
5294 <literal>!~~</literal> and <literal>!~~*</literal> operators that
5295 represent <function>NOT LIKE</function> and <function>NOT
5296 ILIKE</function>, respectively. All of these operators are
5297 <productname>PostgreSQL</productname>-specific. You may see these
5298 operator names in <command>EXPLAIN</command> output and similar
5299 places, since the parser actually translates <function>LIKE</function>
5300 et al. to these operators.
5301 </para>
5303 <para>
5304 The phrases <function>LIKE</function>, <function>ILIKE</function>,
5305 <function>NOT LIKE</function>, and <function>NOT ILIKE</function> are
5306 generally treated as operators
5307 in <productname>PostgreSQL</productname> syntax; for example they can
5308 be used in <replaceable>expression</replaceable>
5309 <replaceable>operator</replaceable> ANY
5310 (<replaceable>subquery</replaceable>) constructs, although
5311 an <literal>ESCAPE</literal> clause cannot be included there. In some
5312 obscure cases it may be necessary to use the underlying operator names
5313 instead.
5314 </para>
5316 <para>
5317 Also see the starts-with operator <literal>^@</literal> and the
5318 corresponding <function>starts_with()</function> function, which are
5319 useful in cases where simply matching the beginning of a string is
5320 needed.
5321 </para>
5322 </sect2>
5325 <sect2 id="functions-similarto-regexp">
5326 <title><function>SIMILAR TO</function> Regular Expressions</title>
5328 <indexterm>
5329 <primary>regular expression</primary>
5330 <!-- <seealso>pattern matching</seealso> breaks index build -->
5331 </indexterm>
5333 <indexterm>
5334 <primary>SIMILAR TO</primary>
5335 </indexterm>
5336 <indexterm>
5337 <primary>substring</primary>
5338 </indexterm>
5340 <synopsis>
5341 <replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5342 <replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
5343 </synopsis>
5345 <para>
5346 The <function>SIMILAR TO</function> operator returns true or
5347 false depending on whether its pattern matches the given string.
5348 It is similar to <function>LIKE</function>, except that it
5349 interprets the pattern using the SQL standard's definition of a
5350 regular expression. SQL regular expressions are a curious cross
5351 between <function>LIKE</function> notation and common (POSIX) regular
5352 expression notation.
5353 </para>
5355 <para>
5356 Like <function>LIKE</function>, the <function>SIMILAR TO</function>
5357 operator succeeds only if its pattern matches the entire string;
5358 this is unlike common regular expression behavior where the pattern
5359 can match any part of the string.
5360 Also like
5361 <function>LIKE</function>, <function>SIMILAR TO</function> uses
5362 <literal>_</literal> and <literal>%</literal> as wildcard characters denoting
5363 any single character and any string, respectively (these are
5364 comparable to <literal>.</literal> and <literal>.*</literal> in POSIX regular
5365 expressions).
5366 </para>
5368 <para>
5369 In addition to these facilities borrowed from <function>LIKE</function>,
5370 <function>SIMILAR TO</function> supports these pattern-matching
5371 metacharacters borrowed from POSIX regular expressions:
5373 <itemizedlist>
5374 <listitem>
5375 <para>
5376 <literal>|</literal> denotes alternation (either of two alternatives).
5377 </para>
5378 </listitem>
5379 <listitem>
5380 <para>
5381 <literal>*</literal> denotes repetition of the previous item zero
5382 or more times.
5383 </para>
5384 </listitem>
5385 <listitem>
5386 <para>
5387 <literal>+</literal> denotes repetition of the previous item one
5388 or more times.
5389 </para>
5390 </listitem>
5391 <listitem>
5392 <para>
5393 <literal>?</literal> denotes repetition of the previous item zero
5394 or one time.
5395 </para>
5396 </listitem>
5397 <listitem>
5398 <para>
5399 <literal>{</literal><replaceable>m</replaceable><literal>}</literal> denotes repetition
5400 of the previous item exactly <replaceable>m</replaceable> times.
5401 </para>
5402 </listitem>
5403 <listitem>
5404 <para>
5405 <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> denotes repetition
5406 of the previous item <replaceable>m</replaceable> or more times.
5407 </para>
5408 </listitem>
5409 <listitem>
5410 <para>
5411 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
5412 denotes repetition of the previous item at least <replaceable>m</replaceable> and
5413 not more than <replaceable>n</replaceable> times.
5414 </para>
5415 </listitem>
5416 <listitem>
5417 <para>
5418 Parentheses <literal>()</literal> can be used to group items into
5419 a single logical item.
5420 </para>
5421 </listitem>
5422 <listitem>
5423 <para>
5424 A bracket expression <literal>[...]</literal> specifies a character
5425 class, just as in POSIX regular expressions.
5426 </para>
5427 </listitem>
5428 </itemizedlist>
5430 Notice that the period (<literal>.</literal>) is not a metacharacter
5431 for <function>SIMILAR TO</function>.
5432 </para>
5434 <para>
5435 As with <function>LIKE</function>, a backslash disables the special
5436 meaning of any of these metacharacters. A different escape character
5437 can be specified with <literal>ESCAPE</literal>, or the escape
5438 capability can be disabled by writing <literal>ESCAPE ''</literal>.
5439 </para>
5441 <para>
5442 According to the SQL standard, omitting <literal>ESCAPE</literal>
5443 means there is no escape character (rather than defaulting to a
5444 backslash), and a zero-length <literal>ESCAPE</literal> value is
5445 disallowed. <productname>PostgreSQL</productname>'s behavior in
5446 this regard is therefore slightly nonstandard.
5447 </para>
5449 <para>
5450 Another nonstandard extension is that following the escape character
5451 with a letter or digit provides access to the escape sequences
5452 defined for POSIX regular expressions; see
5453 <xref linkend="posix-character-entry-escapes-table"/>,
5454 <xref linkend="posix-class-shorthand-escapes-table"/>, and
5455 <xref linkend="posix-constraint-escapes-table"/> below.
5456 </para>
5458 <para>
5459 Some examples:
5460 <programlisting>
5461 'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation>
5462 'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation>
5463 'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation>
5464 'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation>
5465 '-abc-' SIMILAR TO '%\mabc\M%' <lineannotation>true</lineannotation>
5466 'xabcy' SIMILAR TO '%\mabc\M%' <lineannotation>false</lineannotation>
5467 </programlisting>
5468 </para>
5470 <para>
5471 The <function>substring</function> function with three parameters
5472 provides extraction of a substring that matches an SQL
5473 regular expression pattern. The function can be written according
5474 to standard SQL syntax:
5475 <synopsis>
5476 substring(<replaceable>string</replaceable> similar <replaceable>pattern</replaceable> escape <replaceable>escape-character</replaceable>)
5477 </synopsis>
5478 or using the now obsolete SQL:1999 syntax:
5479 <synopsis>
5480 substring(<replaceable>string</replaceable> from <replaceable>pattern</replaceable> for <replaceable>escape-character</replaceable>)
5481 </synopsis>
5482 or as a plain three-argument function:
5483 <synopsis>
5484 substring(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>escape-character</replaceable>)
5485 </synopsis>
5486 As with <literal>SIMILAR TO</literal>, the
5487 specified pattern must match the entire data string, or else the
5488 function fails and returns null. To indicate the part of the
5489 pattern for which the matching data sub-string is of interest,
5490 the pattern should contain
5491 two occurrences of the escape character followed by a double quote
5492 (<literal>"</literal>). <!-- " font-lock sanity -->
5493 The text matching the portion of the pattern
5494 between these separators is returned when the match is successful.
5495 </para>
5497 <para>
5498 The escape-double-quote separators actually
5499 divide <function>substring</function>'s pattern into three independent
5500 regular expressions; for example, a vertical bar (<literal>|</literal>)
5501 in any of the three sections affects only that section. Also, the first
5502 and third of these regular expressions are defined to match the smallest
5503 possible amount of text, not the largest, when there is any ambiguity
5504 about how much of the data string matches which pattern. (In POSIX
5505 parlance, the first and third regular expressions are forced to be
5506 non-greedy.)
5507 </para>
5509 <para>
5510 As an extension to the SQL standard, <productname>PostgreSQL</productname>
5511 allows there to be just one escape-double-quote separator, in which case
5512 the third regular expression is taken as empty; or no separators, in which
5513 case the first and third regular expressions are taken as empty.
5514 </para>
5516 <para>
5517 Some examples, with <literal>#&quot;</literal> delimiting the return string:
5518 <programlisting>
5519 substring('foobar' similar '%#"o_b#"%' escape '#') <lineannotation>oob</lineannotation>
5520 substring('foobar' similar '#"o_b#"%' escape '#') <lineannotation>NULL</lineannotation>
5521 </programlisting>
5522 </para>
5523 </sect2>
5525 <sect2 id="functions-posix-regexp">
5526 <title><acronym>POSIX</acronym> Regular Expressions</title>
5528 <indexterm zone="functions-posix-regexp">
5529 <primary>regular expression</primary>
5530 <seealso>pattern matching</seealso>
5531 </indexterm>
5532 <indexterm>
5533 <primary>substring</primary>
5534 </indexterm>
5535 <indexterm>
5536 <primary>regexp_count</primary>
5537 </indexterm>
5538 <indexterm>
5539 <primary>regexp_instr</primary>
5540 </indexterm>
5541 <indexterm>
5542 <primary>regexp_like</primary>
5543 </indexterm>
5544 <indexterm>
5545 <primary>regexp_match</primary>
5546 </indexterm>
5547 <indexterm>
5548 <primary>regexp_matches</primary>
5549 </indexterm>
5550 <indexterm>
5551 <primary>regexp_replace</primary>
5552 </indexterm>
5553 <indexterm>
5554 <primary>regexp_split_to_table</primary>
5555 </indexterm>
5556 <indexterm>
5557 <primary>regexp_split_to_array</primary>
5558 </indexterm>
5559 <indexterm>
5560 <primary>regexp_substr</primary>
5561 </indexterm>
5563 <para>
5564 <xref linkend="functions-posix-table"/> lists the available
5565 operators for pattern matching using POSIX regular expressions.
5566 </para>
5568 <table id="functions-posix-table">
5569 <title>Regular Expression Match Operators</title>
5571 <tgroup cols="1">
5572 <thead>
5573 <row>
5574 <entry role="func_table_entry"><para role="func_signature">
5575 Operator
5576 </para>
5577 <para>
5578 Description
5579 </para>
5580 <para>
5581 Example(s)
5582 </para></entry>
5583 </row>
5584 </thead>
5586 <tbody>
5587 <row>
5588 <entry role="func_table_entry"><para role="func_signature">
5589 <type>text</type> <literal>~</literal> <type>text</type>
5590 <returnvalue>boolean</returnvalue>
5591 </para>
5592 <para>
5593 String matches regular expression, case sensitively
5594 </para>
5595 <para>
5596 <literal>'thomas' ~ 't.*ma'</literal>
5597 <returnvalue>t</returnvalue>
5598 </para></entry>
5599 </row>
5601 <row>
5602 <entry role="func_table_entry"><para role="func_signature">
5603 <type>text</type> <literal>~*</literal> <type>text</type>
5604 <returnvalue>boolean</returnvalue>
5605 </para>
5606 <para>
5607 String matches regular expression, case-insensitively
5608 </para>
5609 <para>
5610 <literal>'thomas' ~* 'T.*ma'</literal>
5611 <returnvalue>t</returnvalue>
5612 </para></entry>
5613 </row>
5615 <row>
5616 <entry role="func_table_entry"><para role="func_signature">
5617 <type>text</type> <literal>!~</literal> <type>text</type>
5618 <returnvalue>boolean</returnvalue>
5619 </para>
5620 <para>
5621 String does not match regular expression, case sensitively
5622 </para>
5623 <para>
5624 <literal>'thomas' !~ 't.*max'</literal>
5625 <returnvalue>t</returnvalue>
5626 </para></entry>
5627 </row>
5629 <row>
5630 <entry role="func_table_entry"><para role="func_signature">
5631 <type>text</type> <literal>!~*</literal> <type>text</type>
5632 <returnvalue>boolean</returnvalue>
5633 </para>
5634 <para>
5635 String does not match regular expression, case-insensitively
5636 </para>
5637 <para>
5638 <literal>'thomas' !~* 'T.*ma'</literal>
5639 <returnvalue>f</returnvalue>
5640 </para></entry>
5641 </row>
5642 </tbody>
5643 </tgroup>
5644 </table>
5646 <para>
5647 <acronym>POSIX</acronym> regular expressions provide a more
5648 powerful means for pattern matching than the <function>LIKE</function> and
5649 <function>SIMILAR TO</function> operators.
5650 Many Unix tools such as <command>egrep</command>,
5651 <command>sed</command>, or <command>awk</command> use a pattern
5652 matching language that is similar to the one described here.
5653 </para>
5655 <para>
5656 A regular expression is a character sequence that is an
5657 abbreviated definition of a set of strings (a <firstterm>regular
5658 set</firstterm>). A string is said to match a regular expression
5659 if it is a member of the regular set described by the regular
5660 expression. As with <function>LIKE</function>, pattern characters
5661 match string characters exactly unless they are special characters
5662 in the regular expression language &mdash; but regular expressions use
5663 different special characters than <function>LIKE</function> does.
5664 Unlike <function>LIKE</function> patterns, a
5665 regular expression is allowed to match anywhere within a string, unless
5666 the regular expression is explicitly anchored to the beginning or
5667 end of the string.
5668 </para>
5670 <para>
5671 Some examples:
5672 <programlisting>
5673 'abcd' ~ 'bc' <lineannotation>true</lineannotation>
5674 'abcd' ~ 'a.c' <lineannotation>true &mdash; dot matches any character</lineannotation>
5675 'abcd' ~ 'a.*d' <lineannotation>true &mdash; <literal>*</literal> repeats the preceding pattern item</lineannotation>
5676 'abcd' ~ '(b|x)' <lineannotation>true &mdash; <literal>|</literal> means OR, parentheses group</lineannotation>
5677 'abcd' ~ '^a' <lineannotation>true &mdash; <literal>^</literal> anchors to start of string</lineannotation>
5678 'abcd' ~ '^(b|c)' <lineannotation>false &mdash; would match except for anchoring</lineannotation>
5679 </programlisting>
5680 </para>
5682 <para>
5683 The <acronym>POSIX</acronym> pattern language is described in much
5684 greater detail below.
5685 </para>
5687 <para>
5688 The <function>substring</function> function with two parameters,
5689 <function>substring(<replaceable>string</replaceable> from
5690 <replaceable>pattern</replaceable>)</function>, provides extraction of a
5691 substring
5692 that matches a POSIX regular expression pattern. It returns null if
5693 there is no match, otherwise the first portion of the text that matched the
5694 pattern. But if the pattern contains any parentheses, the portion
5695 of the text that matched the first parenthesized subexpression (the
5696 one whose left parenthesis comes first) is
5697 returned. You can put parentheses around the whole expression
5698 if you want to use parentheses within it without triggering this
5699 exception. If you need parentheses in the pattern before the
5700 subexpression you want to extract, see the non-capturing parentheses
5701 described below.
5702 </para>
5704 <para>
5705 Some examples:
5706 <programlisting>
5707 substring('foobar' from 'o.b') <lineannotation>oob</lineannotation>
5708 substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation>
5709 </programlisting>
5710 </para>
5712 <para>
5713 The <function>regexp_count</function> function counts the number of
5714 places where a POSIX regular expression pattern matches a string.
5715 It has the syntax
5716 <function>regexp_count</function>(<replaceable>string</replaceable>,
5717 <replaceable>pattern</replaceable>
5718 <optional>, <replaceable>start</replaceable>
5719 <optional>, <replaceable>flags</replaceable>
5720 </optional></optional>).
5721 <replaceable>pattern</replaceable> is searched for
5722 in <replaceable>string</replaceable>, normally from the beginning of
5723 the string, but if the <replaceable>start</replaceable> parameter is
5724 provided then beginning from that character index.
5725 The <replaceable>flags</replaceable> parameter is an optional text
5726 string containing zero or more single-letter flags that change the
5727 function's behavior. For example, including <literal>i</literal> in
5728 <replaceable>flags</replaceable> specifies case-insensitive matching.
5729 Supported flags are described in
5730 <xref linkend="posix-embedded-options-table"/>.
5731 </para>
5733 <para>
5734 Some examples:
5735 <programlisting>
5736 regexp_count('ABCABCAXYaxy', 'A.') <lineannotation>3</lineannotation>
5737 regexp_count('ABCABCAXYaxy', 'A.', 1, 'i') <lineannotation>4</lineannotation>
5738 </programlisting>
5739 </para>
5741 <para>
5742 The <function>regexp_instr</function> function returns the starting or
5743 ending position of the <replaceable>N</replaceable>'th match of a
5744 POSIX regular expression pattern to a string, or zero if there is no
5745 such match. It has the syntax
5746 <function>regexp_instr</function>(<replaceable>string</replaceable>,
5747 <replaceable>pattern</replaceable>
5748 <optional>, <replaceable>start</replaceable>
5749 <optional>, <replaceable>N</replaceable>
5750 <optional>, <replaceable>endoption</replaceable>
5751 <optional>, <replaceable>flags</replaceable>
5752 <optional>, <replaceable>subexpr</replaceable>
5753 </optional></optional></optional></optional></optional>).
5754 <replaceable>pattern</replaceable> is searched for
5755 in <replaceable>string</replaceable>, normally from the beginning of
5756 the string, but if the <replaceable>start</replaceable> parameter is
5757 provided then beginning from that character index.
5758 If <replaceable>N</replaceable> is specified
5759 then the <replaceable>N</replaceable>'th match of the pattern
5760 is located, otherwise the first match is located.
5761 If the <replaceable>endoption</replaceable> parameter is omitted or
5762 specified as zero, the function returns the position of the first
5763 character of the match. Otherwise, <replaceable>endoption</replaceable>
5764 must be one, and the function returns the position of the character
5765 following the match.
5766 The <replaceable>flags</replaceable> parameter is an optional text
5767 string containing zero or more single-letter flags that change the
5768 function's behavior. Supported flags are described
5769 in <xref linkend="posix-embedded-options-table"/>.
5770 For a pattern containing parenthesized
5771 subexpressions, <replaceable>subexpr</replaceable> is an integer
5772 indicating which subexpression is of interest: the result identifies
5773 the position of the substring matching that subexpression.
5774 Subexpressions are numbered in the order of their leading parentheses.
5775 When <replaceable>subexpr</replaceable> is omitted or zero, the result
5776 identifies the position of the whole match regardless of
5777 parenthesized subexpressions.
5778 </para>
5780 <para>
5781 Some examples:
5782 <programlisting>
5783 regexp_instr('number of your street, town zip, FR', '[^,]+', 1, 2)
5784 <lineannotation>23</lineannotation>
5785 regexp_instr('ABCDEFGHI', '(c..)(...)', 1, 1, 0, 'i', 2)
5786 <lineannotation>6</lineannotation>
5787 </programlisting>
5788 </para>
5790 <para>
5791 The <function>regexp_like</function> function checks whether a match
5792 of a POSIX regular expression pattern occurs within a string,
5793 returning boolean true or false. It has the syntax
5794 <function>regexp_like</function>(<replaceable>string</replaceable>,
5795 <replaceable>pattern</replaceable>
5796 <optional>, <replaceable>flags</replaceable> </optional>).
5797 The <replaceable>flags</replaceable> parameter is an optional text
5798 string containing zero or more single-letter flags that change the
5799 function's behavior. Supported flags are described
5800 in <xref linkend="posix-embedded-options-table"/>.
5801 This function has the same results as the <literal>~</literal>
5802 operator if no flags are specified. If only the <literal>i</literal>
5803 flag is specified, it has the same results as
5804 the <literal>~*</literal> operator.
5805 </para>
5807 <para>
5808 Some examples:
5809 <programlisting>
5810 regexp_like('Hello World', 'world') <lineannotation>false</lineannotation>
5811 regexp_like('Hello World', 'world', 'i') <lineannotation>true</lineannotation>
5812 </programlisting>
5813 </para>
5815 <para>
5816 The <function>regexp_match</function> function returns a text array of
5817 matching substring(s) within the first match of a POSIX
5818 regular expression pattern to a string. It has the syntax
5819 <function>regexp_match</function>(<replaceable>string</replaceable>,
5820 <replaceable>pattern</replaceable> <optional>, <replaceable>flags</replaceable> </optional>).
5821 If there is no match, the result is <literal>NULL</literal>.
5822 If a match is found, and the <replaceable>pattern</replaceable> contains no
5823 parenthesized subexpressions, then the result is a single-element text
5824 array containing the substring matching the whole pattern.
5825 If a match is found, and the <replaceable>pattern</replaceable> contains
5826 parenthesized subexpressions, then the result is a text array
5827 whose <replaceable>n</replaceable>'th element is the substring matching
5828 the <replaceable>n</replaceable>'th parenthesized subexpression of
5829 the <replaceable>pattern</replaceable> (not counting <quote>non-capturing</quote>
5830 parentheses; see below for details).
5831 The <replaceable>flags</replaceable> parameter is an optional text string
5832 containing zero or more single-letter flags that change the function's
5833 behavior. Supported flags are described
5834 in <xref linkend="posix-embedded-options-table"/>.
5835 </para>
5837 <para>
5838 Some examples:
5839 <programlisting>
5840 SELECT regexp_match('foobarbequebaz', 'bar.*que');
5841 regexp_match
5842 --------------
5843 {barbeque}
5844 (1 row)
5846 SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
5847 regexp_match
5848 --------------
5849 {bar,beque}
5850 (1 row)
5851 </programlisting>
5852 </para>
5854 <tip>
5855 <para>
5856 In the common case where you just want the whole matching substring
5857 or <literal>NULL</literal> for no match, the best solution is to
5858 use <function>regexp_substr()</function>.
5859 However, <function>regexp_substr()</function> only exists
5860 in <productname>PostgreSQL</productname> version 15 and up. When
5861 working in older versions, you can extract the first element
5862 of <function>regexp_match()</function>'s result, for example:
5863 <programlisting>
5864 SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[1];
5865 regexp_match
5866 --------------
5867 barbeque
5868 (1 row)
5869 </programlisting>
5870 </para>
5871 </tip>
5873 <para>
5874 The <function>regexp_matches</function> function returns a set of text arrays
5875 of matching substring(s) within matches of a POSIX regular
5876 expression pattern to a string. It has the same syntax as
5877 <function>regexp_match</function>.
5878 This function returns no rows if there is no match, one row if there is
5879 a match and the <literal>g</literal> flag is not given, or <replaceable>N</replaceable>
5880 rows if there are <replaceable>N</replaceable> matches and the <literal>g</literal> flag
5881 is given. Each returned row is a text array containing the whole
5882 matched substring or the substrings matching parenthesized
5883 subexpressions of the <replaceable>pattern</replaceable>, just as described above
5884 for <function>regexp_match</function>.
5885 <function>regexp_matches</function> accepts all the flags shown
5886 in <xref linkend="posix-embedded-options-table"/>, plus
5887 the <literal>g</literal> flag which commands it to return all matches, not
5888 just the first one.
5889 </para>
5891 <para>
5892 Some examples:
5893 <programlisting>
5894 SELECT regexp_matches('foo', 'not there');
5895 regexp_matches
5896 ----------------
5897 (0 rows)
5899 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
5900 regexp_matches
5901 ----------------
5902 {bar,beque}
5903 {bazil,barf}
5904 (2 rows)
5905 </programlisting>
5906 </para>
5908 <tip>
5909 <para>
5910 In most cases <function>regexp_matches()</function> should be used with
5911 the <literal>g</literal> flag, since if you only want the first match, it's
5912 easier and more efficient to use <function>regexp_match()</function>.
5913 However, <function>regexp_match()</function> only exists
5914 in <productname>PostgreSQL</productname> version 10 and up. When working in older
5915 versions, a common trick is to place a <function>regexp_matches()</function>
5916 call in a sub-select, for example:
5917 <programlisting>
5918 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
5919 </programlisting>
5920 This produces a text array if there's a match, or <literal>NULL</literal> if
5921 not, the same as <function>regexp_match()</function> would do. Without the
5922 sub-select, this query would produce no output at all for table rows
5923 without a match, which is typically not the desired behavior.
5924 </para>
5925 </tip>
5927 <para>
5928 The <function>regexp_replace</function> function provides substitution of
5929 new text for substrings that match POSIX regular expression patterns.
5930 It has the syntax
5931 <function>regexp_replace</function>(<replaceable>source</replaceable>,
5932 <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>
5933 <optional>, <replaceable>start</replaceable>
5934 <optional>, <replaceable>N</replaceable>
5935 </optional></optional>
5936 <optional>, <replaceable>flags</replaceable> </optional>).
5937 (Notice that <replaceable>N</replaceable> cannot be specified
5938 unless <replaceable>start</replaceable> is,
5939 but <replaceable>flags</replaceable> can be given in any case.)
5940 The <replaceable>source</replaceable> string is returned unchanged if
5941 there is no match to the <replaceable>pattern</replaceable>. If there is a
5942 match, the <replaceable>source</replaceable> string is returned with the
5943 <replaceable>replacement</replaceable> string substituted for the matching
5944 substring. The <replaceable>replacement</replaceable> string can contain
5945 <literal>\</literal><replaceable>n</replaceable>, where <replaceable>n</replaceable> is 1
5946 through 9, to indicate that the source substring matching the
5947 <replaceable>n</replaceable>'th parenthesized subexpression of the pattern should be
5948 inserted, and it can contain <literal>\&amp;</literal> to indicate that the
5949 substring matching the entire pattern should be inserted. Write
5950 <literal>\\</literal> if you need to put a literal backslash in the replacement
5951 text.
5952 <replaceable>pattern</replaceable> is searched for
5953 in <replaceable>string</replaceable>, normally from the beginning of
5954 the string, but if the <replaceable>start</replaceable> parameter is
5955 provided then beginning from that character index.
5956 By default, only the first match of the pattern is replaced.
5957 If <replaceable>N</replaceable> is specified and is greater than zero,
5958 then the <replaceable>N</replaceable>'th match of the pattern
5959 is replaced.
5960 If the <literal>g</literal> flag is given, or
5961 if <replaceable>N</replaceable> is specified and is zero, then all
5962 matches at or after the <replaceable>start</replaceable> position are
5963 replaced. (The <literal>g</literal> flag is ignored
5964 when <replaceable>N</replaceable> is specified.)
5965 The <replaceable>flags</replaceable> parameter is an optional text
5966 string containing zero or more single-letter flags that change the
5967 function's behavior. Supported flags (though
5968 not <literal>g</literal>) are
5969 described in <xref linkend="posix-embedded-options-table"/>.
5970 </para>
5972 <para>
5973 Some examples:
5974 <programlisting>
5975 regexp_replace('foobarbaz', 'b..', 'X')
5976 <lineannotation>fooXbaz</lineannotation>
5977 regexp_replace('foobarbaz', 'b..', 'X', 'g')
5978 <lineannotation>fooXX</lineannotation>
5979 regexp_replace('foobarbaz', 'b(..)', 'X\1Y', 'g')
5980 <lineannotation>fooXarYXazY</lineannotation>
5981 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 0, 'i')
5982 <lineannotation>X PXstgrXSQL fXnctXXn</lineannotation>
5983 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X', 1, 3, 'i')
5984 <lineannotation>A PostgrXSQL function</lineannotation>
5985 </programlisting>
5986 </para>
5988 <para>
5989 The <function>regexp_split_to_table</function> function splits a string using a POSIX
5990 regular expression pattern as a delimiter. It has the syntax
5991 <function>regexp_split_to_table</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
5992 <optional>, <replaceable>flags</replaceable> </optional>).
5993 If there is no match to the <replaceable>pattern</replaceable>, the function returns the
5994 <replaceable>string</replaceable>. If there is at least one match, for each match it returns
5995 the text from the end of the last match (or the beginning of the string)
5996 to the beginning of the match. When there are no more matches, it
5997 returns the text from the end of the last match to the end of the string.
5998 The <replaceable>flags</replaceable> parameter is an optional text string containing
5999 zero or more single-letter flags that change the function's behavior.
6000 <function>regexp_split_to_table</function> supports the flags described in
6001 <xref linkend="posix-embedded-options-table"/>.
6002 </para>
6004 <para>
6005 The <function>regexp_split_to_array</function> function behaves the same as
6006 <function>regexp_split_to_table</function>, except that <function>regexp_split_to_array</function>
6007 returns its result as an array of <type>text</type>. It has the syntax
6008 <function>regexp_split_to_array</function>(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>
6009 <optional>, <replaceable>flags</replaceable> </optional>).
6010 The parameters are the same as for <function>regexp_split_to_table</function>.
6011 </para>
6013 <para>
6014 Some examples:
6015 <programlisting>
6016 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo;
6018 -------
6020 quick
6021 brown
6023 jumps
6024 over
6026 lazy
6028 (9 rows)
6030 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+');
6031 regexp_split_to_array
6032 -----------------------------------------------
6033 {the,quick,brown,fox,jumps,over,the,lazy,dog}
6034 (1 row)
6036 SELECT foo FROM regexp_split_to_table('the quick brown fox', '\s*') AS foo;
6038 -----
6055 (16 rows)
6056 </programlisting>
6057 </para>
6059 <para>
6060 As the last example demonstrates, the regexp split functions ignore
6061 zero-length matches that occur at the start or end of the string
6062 or immediately after a previous match. This is contrary to the strict
6063 definition of regexp matching that is implemented by
6064 the other regexp functions, but is usually the most convenient behavior
6065 in practice. Other software systems such as Perl use similar definitions.
6066 </para>
6068 <para>
6069 The <function>regexp_substr</function> function returns the substring
6070 that matches a POSIX regular expression pattern,
6071 or <literal>NULL</literal> if there is no match. It has the syntax
6072 <function>regexp_substr</function>(<replaceable>string</replaceable>,
6073 <replaceable>pattern</replaceable>
6074 <optional>, <replaceable>start</replaceable>
6075 <optional>, <replaceable>N</replaceable>
6076 <optional>, <replaceable>flags</replaceable>
6077 <optional>, <replaceable>subexpr</replaceable>
6078 </optional></optional></optional></optional>).
6079 <replaceable>pattern</replaceable> is searched for
6080 in <replaceable>string</replaceable>, normally from the beginning of
6081 the string, but if the <replaceable>start</replaceable> parameter is
6082 provided then beginning from that character index.
6083 If <replaceable>N</replaceable> is specified
6084 then the <replaceable>N</replaceable>'th match of the pattern
6085 is returned, otherwise the first match is returned.
6086 The <replaceable>flags</replaceable> parameter is an optional text
6087 string containing zero or more single-letter flags that change the
6088 function's behavior. Supported flags are described
6089 in <xref linkend="posix-embedded-options-table"/>.
6090 For a pattern containing parenthesized
6091 subexpressions, <replaceable>subexpr</replaceable> is an integer
6092 indicating which subexpression is of interest: the result is the
6093 substring matching that subexpression.
6094 Subexpressions are numbered in the order of their leading parentheses.
6095 When <replaceable>subexpr</replaceable> is omitted or zero, the result
6096 is the whole match regardless of parenthesized subexpressions.
6097 </para>
6099 <para>
6100 Some examples:
6101 <programlisting>
6102 regexp_substr('number of your street, town zip, FR', '[^,]+', 1, 2)
6103 <lineannotation> town zip</lineannotation>
6104 regexp_substr('ABCDEFGHI', '(c..)(...)', 1, 1, 'i', 2)
6105 <lineannotation>FGH</lineannotation>
6106 </programlisting>
6107 </para>
6109 <!-- derived from the re_syntax.n man page -->
6111 <sect3 id="posix-syntax-details">
6112 <title>Regular Expression Details</title>
6114 <para>
6115 <productname>PostgreSQL</productname>'s regular expressions are implemented
6116 using a software package written by Henry Spencer. Much of
6117 the description of regular expressions below is copied verbatim from his
6118 manual.
6119 </para>
6121 <para>
6122 Regular expressions (<acronym>RE</acronym>s), as defined in
6123 <acronym>POSIX</acronym> 1003.2, come in two forms:
6124 <firstterm>extended</firstterm> <acronym>RE</acronym>s or <acronym>ERE</acronym>s
6125 (roughly those of <command>egrep</command>), and
6126 <firstterm>basic</firstterm> <acronym>RE</acronym>s or <acronym>BRE</acronym>s
6127 (roughly those of <command>ed</command>).
6128 <productname>PostgreSQL</productname> supports both forms, and
6129 also implements some extensions
6130 that are not in the POSIX standard, but have become widely used
6131 due to their availability in programming languages such as Perl and Tcl.
6132 <acronym>RE</acronym>s using these non-POSIX extensions are called
6133 <firstterm>advanced</firstterm> <acronym>RE</acronym>s or <acronym>ARE</acronym>s
6134 in this documentation. AREs are almost an exact superset of EREs,
6135 but BREs have several notational incompatibilities (as well as being
6136 much more limited).
6137 We first describe the ARE and ERE forms, noting features that apply
6138 only to AREs, and then describe how BREs differ.
6139 </para>
6141 <note>
6142 <para>
6143 <productname>PostgreSQL</productname> always initially presumes that a regular
6144 expression follows the ARE rules. However, the more limited ERE or
6145 BRE rules can be chosen by prepending an <firstterm>embedded option</firstterm>
6146 to the RE pattern, as described in <xref linkend="posix-metasyntax"/>.
6147 This can be useful for compatibility with applications that expect
6148 exactly the <acronym>POSIX</acronym> 1003.2 rules.
6149 </para>
6150 </note>
6152 <para>
6153 A regular expression is defined as one or more
6154 <firstterm>branches</firstterm>, separated by
6155 <literal>|</literal>. It matches anything that matches one of the
6156 branches.
6157 </para>
6159 <para>
6160 A branch is zero or more <firstterm>quantified atoms</firstterm> or
6161 <firstterm>constraints</firstterm>, concatenated.
6162 It matches a match for the first, followed by a match for the second, etc.;
6163 an empty branch matches the empty string.
6164 </para>
6166 <para>
6167 A quantified atom is an <firstterm>atom</firstterm> possibly followed
6168 by a single <firstterm>quantifier</firstterm>.
6169 Without a quantifier, it matches a match for the atom.
6170 With a quantifier, it can match some number of matches of the atom.
6171 An <firstterm>atom</firstterm> can be any of the possibilities
6172 shown in <xref linkend="posix-atoms-table"/>.
6173 The possible quantifiers and their meanings are shown in
6174 <xref linkend="posix-quantifiers-table"/>.
6175 </para>
6177 <para>
6178 A <firstterm>constraint</firstterm> matches an empty string, but matches only when
6179 specific conditions are met. A constraint can be used where an atom
6180 could be used, except it cannot be followed by a quantifier.
6181 The simple constraints are shown in
6182 <xref linkend="posix-constraints-table"/>;
6183 some more constraints are described later.
6184 </para>
6187 <table id="posix-atoms-table">
6188 <title>Regular Expression Atoms</title>
6190 <tgroup cols="2">
6191 <thead>
6192 <row>
6193 <entry>Atom</entry>
6194 <entry>Description</entry>
6195 </row>
6196 </thead>
6198 <tbody>
6199 <row>
6200 <entry> <literal>(</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6201 <entry> (where <replaceable>re</replaceable> is any regular expression)
6202 matches a match for
6203 <replaceable>re</replaceable>, with the match noted for possible reporting </entry>
6204 </row>
6206 <row>
6207 <entry> <literal>(?:</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6208 <entry> as above, but the match is not noted for reporting
6209 (a <quote>non-capturing</quote> set of parentheses)
6210 (AREs only) </entry>
6211 </row>
6213 <row>
6214 <entry> <literal>.</literal> </entry>
6215 <entry> matches any single character </entry>
6216 </row>
6218 <row>
6219 <entry> <literal>[</literal><replaceable>chars</replaceable><literal>]</literal> </entry>
6220 <entry> a <firstterm>bracket expression</firstterm>,
6221 matching any one of the <replaceable>chars</replaceable> (see
6222 <xref linkend="posix-bracket-expressions"/> for more detail) </entry>
6223 </row>
6225 <row>
6226 <entry> <literal>\</literal><replaceable>k</replaceable> </entry>
6227 <entry> (where <replaceable>k</replaceable> is a non-alphanumeric character)
6228 matches that character taken as an ordinary character,
6229 e.g., <literal>\\</literal> matches a backslash character </entry>
6230 </row>
6232 <row>
6233 <entry> <literal>\</literal><replaceable>c</replaceable> </entry>
6234 <entry> where <replaceable>c</replaceable> is alphanumeric
6235 (possibly followed by other characters)
6236 is an <firstterm>escape</firstterm>, see <xref linkend="posix-escape-sequences"/>
6237 (AREs only; in EREs and BREs, this matches <replaceable>c</replaceable>) </entry>
6238 </row>
6240 <row>
6241 <entry> <literal>{</literal> </entry>
6242 <entry> when followed by a character other than a digit,
6243 matches the left-brace character <literal>{</literal>;
6244 when followed by a digit, it is the beginning of a
6245 <replaceable>bound</replaceable> (see below) </entry>
6246 </row>
6248 <row>
6249 <entry> <replaceable>x</replaceable> </entry>
6250 <entry> where <replaceable>x</replaceable> is a single character with no other
6251 significance, matches that character </entry>
6252 </row>
6253 </tbody>
6254 </tgroup>
6255 </table>
6257 <para>
6258 An RE cannot end with a backslash (<literal>\</literal>).
6259 </para>
6261 <note>
6262 <para>
6263 If you have <xref linkend="guc-standard-conforming-strings"/> turned off,
6264 any backslashes you write in literal string constants will need to be
6265 doubled. See <xref linkend="sql-syntax-strings"/> for more information.
6266 </para>
6267 </note>
6269 <table id="posix-quantifiers-table">
6270 <title>Regular Expression Quantifiers</title>
6272 <tgroup cols="2">
6273 <thead>
6274 <row>
6275 <entry>Quantifier</entry>
6276 <entry>Matches</entry>
6277 </row>
6278 </thead>
6280 <tbody>
6281 <row>
6282 <entry> <literal>*</literal> </entry>
6283 <entry> a sequence of 0 or more matches of the atom </entry>
6284 </row>
6286 <row>
6287 <entry> <literal>+</literal> </entry>
6288 <entry> a sequence of 1 or more matches of the atom </entry>
6289 </row>
6291 <row>
6292 <entry> <literal>?</literal> </entry>
6293 <entry> a sequence of 0 or 1 matches of the atom </entry>
6294 </row>
6296 <row>
6297 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6298 <entry> a sequence of exactly <replaceable>m</replaceable> matches of the atom </entry>
6299 </row>
6301 <row>
6302 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6303 <entry> a sequence of <replaceable>m</replaceable> or more matches of the atom </entry>
6304 </row>
6306 <row>
6307 <entry>
6308 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6309 <entry> a sequence of <replaceable>m</replaceable> through <replaceable>n</replaceable>
6310 (inclusive) matches of the atom; <replaceable>m</replaceable> cannot exceed
6311 <replaceable>n</replaceable> </entry>
6312 </row>
6314 <row>
6315 <entry> <literal>*?</literal> </entry>
6316 <entry> non-greedy version of <literal>*</literal> </entry>
6317 </row>
6319 <row>
6320 <entry> <literal>+?</literal> </entry>
6321 <entry> non-greedy version of <literal>+</literal> </entry>
6322 </row>
6324 <row>
6325 <entry> <literal>??</literal> </entry>
6326 <entry> non-greedy version of <literal>?</literal> </entry>
6327 </row>
6329 <row>
6330 <entry> <literal>{</literal><replaceable>m</replaceable><literal>}?</literal> </entry>
6331 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>}</literal> </entry>
6332 </row>
6334 <row>
6335 <entry> <literal>{</literal><replaceable>m</replaceable><literal>,}?</literal> </entry>
6336 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,}</literal> </entry>
6337 </row>
6339 <row>
6340 <entry>
6341 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal> </entry>
6342 <entry> non-greedy version of <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal> </entry>
6343 </row>
6344 </tbody>
6345 </tgroup>
6346 </table>
6348 <para>
6349 The forms using <literal>{</literal><replaceable>...</replaceable><literal>}</literal>
6350 are known as <firstterm>bounds</firstterm>.
6351 The numbers <replaceable>m</replaceable> and <replaceable>n</replaceable> within a bound are
6352 unsigned decimal integers with permissible values from 0 to 255 inclusive.
6353 </para>
6355 <para>
6356 <firstterm>Non-greedy</firstterm> quantifiers (available in AREs only) match the
6357 same possibilities as their corresponding normal (<firstterm>greedy</firstterm>)
6358 counterparts, but prefer the smallest number rather than the largest
6359 number of matches.
6360 See <xref linkend="posix-matching-rules"/> for more detail.
6361 </para>
6363 <note>
6364 <para>
6365 A quantifier cannot immediately follow another quantifier, e.g.,
6366 <literal>**</literal> is invalid.
6367 A quantifier cannot
6368 begin an expression or subexpression or follow
6369 <literal>^</literal> or <literal>|</literal>.
6370 </para>
6371 </note>
6373 <table id="posix-constraints-table">
6374 <title>Regular Expression Constraints</title>
6376 <tgroup cols="2">
6377 <thead>
6378 <row>
6379 <entry>Constraint</entry>
6380 <entry>Description</entry>
6381 </row>
6382 </thead>
6384 <tbody>
6385 <row>
6386 <entry> <literal>^</literal> </entry>
6387 <entry> matches at the beginning of the string </entry>
6388 </row>
6390 <row>
6391 <entry> <literal>$</literal> </entry>
6392 <entry> matches at the end of the string </entry>
6393 </row>
6395 <row>
6396 <entry> <literal>(?=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6397 <entry> <firstterm>positive lookahead</firstterm> matches at any point
6398 where a substring matching <replaceable>re</replaceable> begins
6399 (AREs only) </entry>
6400 </row>
6402 <row>
6403 <entry> <literal>(?!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6404 <entry> <firstterm>negative lookahead</firstterm> matches at any point
6405 where no substring matching <replaceable>re</replaceable> begins
6406 (AREs only) </entry>
6407 </row>
6409 <row>
6410 <entry> <literal>(?&lt;=</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6411 <entry> <firstterm>positive lookbehind</firstterm> matches at any point
6412 where a substring matching <replaceable>re</replaceable> ends
6413 (AREs only) </entry>
6414 </row>
6416 <row>
6417 <entry> <literal>(?&lt;!</literal><replaceable>re</replaceable><literal>)</literal> </entry>
6418 <entry> <firstterm>negative lookbehind</firstterm> matches at any point
6419 where no substring matching <replaceable>re</replaceable> ends
6420 (AREs only) </entry>
6421 </row>
6422 </tbody>
6423 </tgroup>
6424 </table>
6426 <para>
6427 Lookahead and lookbehind constraints cannot contain <firstterm>back
6428 references</firstterm> (see <xref linkend="posix-escape-sequences"/>),
6429 and all parentheses within them are considered non-capturing.
6430 </para>
6431 </sect3>
6433 <sect3 id="posix-bracket-expressions">
6434 <title>Bracket Expressions</title>
6436 <para>
6437 A <firstterm>bracket expression</firstterm> is a list of
6438 characters enclosed in <literal>[]</literal>. It normally matches
6439 any single character from the list (but see below). If the list
6440 begins with <literal>^</literal>, it matches any single character
6441 <emphasis>not</emphasis> from the rest of the list.
6442 If two characters
6443 in the list are separated by <literal>-</literal>, this is
6444 shorthand for the full range of characters between those two
6445 (inclusive) in the collating sequence,
6446 e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
6447 any decimal digit. It is illegal for two ranges to share an
6448 endpoint, e.g., <literal>a-c-e</literal>. Ranges are very
6449 collating-sequence-dependent, so portable programs should avoid
6450 relying on them.
6451 </para>
6453 <para>
6454 To include a literal <literal>]</literal> in the list, make it the
6455 first character (after <literal>^</literal>, if that is used). To
6456 include a literal <literal>-</literal>, make it the first or last
6457 character, or the second endpoint of a range. To use a literal
6458 <literal>-</literal> as the first endpoint of a range, enclose it
6459 in <literal>[.</literal> and <literal>.]</literal> to make it a
6460 collating element (see below). With the exception of these characters,
6461 some combinations using <literal>[</literal>
6462 (see next paragraphs), and escapes (AREs only), all other special
6463 characters lose their special significance within a bracket expression.
6464 In particular, <literal>\</literal> is not special when following
6465 ERE or BRE rules, though it is special (as introducing an escape)
6466 in AREs.
6467 </para>
6469 <para>
6470 Within a bracket expression, a collating element (a character, a
6471 multiple-character sequence that collates as if it were a single
6472 character, or a collating-sequence name for either) enclosed in
6473 <literal>[.</literal> and <literal>.]</literal> stands for the
6474 sequence of characters of that collating element. The sequence is
6475 treated as a single element of the bracket expression's list. This
6476 allows a bracket
6477 expression containing a multiple-character collating element to
6478 match more than one character, e.g., if the collating sequence
6479 includes a <literal>ch</literal> collating element, then the RE
6480 <literal>[[.ch.]]*c</literal> matches the first five characters of
6481 <literal>chchcc</literal>.
6482 </para>
6484 <note>
6485 <para>
6486 <productname>PostgreSQL</productname> currently does not support multi-character collating
6487 elements. This information describes possible future behavior.
6488 </para>
6489 </note>
6491 <para>
6492 Within a bracket expression, a collating element enclosed in
6493 <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
6494 class</firstterm>, standing for the sequences of characters of all collating
6495 elements equivalent to that one, including itself. (If there are
6496 no other equivalent collating elements, the treatment is as if the
6497 enclosing delimiters were <literal>[.</literal> and
6498 <literal>.]</literal>.) For example, if <literal>o</literal> and
6499 <literal>^</literal> are the members of an equivalence class, then
6500 <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
6501 <literal>[o^]</literal> are all synonymous. An equivalence class
6502 cannot be an endpoint of a range.
6503 </para>
6505 <para>
6506 Within a bracket expression, the name of a character class
6507 enclosed in <literal>[:</literal> and <literal>:]</literal> stands
6508 for the list of all characters belonging to that class. A character
6509 class cannot be used as an endpoint of a range.
6510 The <acronym>POSIX</acronym> standard defines these character class
6511 names:
6512 <literal>alnum</literal> (letters and numeric digits),
6513 <literal>alpha</literal> (letters),
6514 <literal>blank</literal> (space and tab),
6515 <literal>cntrl</literal> (control characters),
6516 <literal>digit</literal> (numeric digits),
6517 <literal>graph</literal> (printable characters except space),
6518 <literal>lower</literal> (lower-case letters),
6519 <literal>print</literal> (printable characters including space),
6520 <literal>punct</literal> (punctuation),
6521 <literal>space</literal> (any white space),
6522 <literal>upper</literal> (upper-case letters),
6523 and <literal>xdigit</literal> (hexadecimal digits).
6524 The behavior of these standard character classes is generally
6525 consistent across platforms for characters in the 7-bit ASCII set.
6526 Whether a given non-ASCII character is considered to belong to one
6527 of these classes depends on the <firstterm>collation</firstterm>
6528 that is used for the regular-expression function or operator
6529 (see <xref linkend="collation"/>), or by default on the
6530 database's <envar>LC_CTYPE</envar> locale setting (see
6531 <xref linkend="locale"/>). The classification of non-ASCII
6532 characters can vary across platforms even in similarly-named
6533 locales. (But the <literal>C</literal> locale never considers any
6534 non-ASCII characters to belong to any of these classes.)
6535 In addition to these standard character
6536 classes, <productname>PostgreSQL</productname> defines
6537 the <literal>word</literal> character class, which is the same as
6538 <literal>alnum</literal> plus the underscore (<literal>_</literal>)
6539 character, and
6540 the <literal>ascii</literal> character class, which contains exactly
6541 the 7-bit ASCII set.
6542 </para>
6544 <para>
6545 There are two special cases of bracket expressions: the bracket
6546 expressions <literal>[[:&lt;:]]</literal> and
6547 <literal>[[:&gt;:]]</literal> are constraints,
6548 matching empty strings at the beginning
6549 and end of a word respectively. A word is defined as a sequence
6550 of word characters that is neither preceded nor followed by word
6551 characters. A word character is any character belonging to the
6552 <literal>word</literal> character class, that is, any letter, digit,
6553 or underscore. This is an extension, compatible with but not
6554 specified by <acronym>POSIX</acronym> 1003.2, and should be used with
6555 caution in software intended to be portable to other systems.
6556 The constraint escapes described below are usually preferable; they
6557 are no more standard, but are easier to type.
6558 </para>
6559 </sect3>
6561 <sect3 id="posix-escape-sequences">
6562 <title>Regular Expression Escapes</title>
6564 <para>
6565 <firstterm>Escapes</firstterm> are special sequences beginning with <literal>\</literal>
6566 followed by an alphanumeric character. Escapes come in several varieties:
6567 character entry, class shorthands, constraint escapes, and back references.
6568 A <literal>\</literal> followed by an alphanumeric character but not constituting
6569 a valid escape is illegal in AREs.
6570 In EREs, there are no escapes: outside a bracket expression,
6571 a <literal>\</literal> followed by an alphanumeric character merely stands for
6572 that character as an ordinary character, and inside a bracket expression,
6573 <literal>\</literal> is an ordinary character.
6574 (The latter is the one actual incompatibility between EREs and AREs.)
6575 </para>
6577 <para>
6578 <firstterm>Character-entry escapes</firstterm> exist to make it easier to specify
6579 non-printing and other inconvenient characters in REs. They are
6580 shown in <xref linkend="posix-character-entry-escapes-table"/>.
6581 </para>
6583 <para>
6584 <firstterm>Class-shorthand escapes</firstterm> provide shorthands for certain
6585 commonly-used character classes. They are
6586 shown in <xref linkend="posix-class-shorthand-escapes-table"/>.
6587 </para>
6589 <para>
6590 A <firstterm>constraint escape</firstterm> is a constraint,
6591 matching the empty string if specific conditions are met,
6592 written as an escape. They are
6593 shown in <xref linkend="posix-constraint-escapes-table"/>.
6594 </para>
6596 <para>
6597 A <firstterm>back reference</firstterm> (<literal>\</literal><replaceable>n</replaceable>) matches the
6598 same string matched by the previous parenthesized subexpression specified
6599 by the number <replaceable>n</replaceable>
6600 (see <xref linkend="posix-constraint-backref-table"/>). For example,
6601 <literal>([bc])\1</literal> matches <literal>bb</literal> or <literal>cc</literal>
6602 but not <literal>bc</literal> or <literal>cb</literal>.
6603 The subexpression must entirely precede the back reference in the RE.
6604 Subexpressions are numbered in the order of their leading parentheses.
6605 Non-capturing parentheses do not define subexpressions.
6606 The back reference considers only the string characters matched by the
6607 referenced subexpression, not any constraints contained in it. For
6608 example, <literal>(^\d)\1</literal> will match <literal>22</literal>.
6609 </para>
6611 <table id="posix-character-entry-escapes-table">
6612 <title>Regular Expression Character-Entry Escapes</title>
6614 <tgroup cols="2">
6615 <thead>
6616 <row>
6617 <entry>Escape</entry>
6618 <entry>Description</entry>
6619 </row>
6620 </thead>
6622 <tbody>
6623 <row>
6624 <entry> <literal>\a</literal> </entry>
6625 <entry> alert (bell) character, as in C </entry>
6626 </row>
6628 <row>
6629 <entry> <literal>\b</literal> </entry>
6630 <entry> backspace, as in C </entry>
6631 </row>
6633 <row>
6634 <entry> <literal>\B</literal> </entry>
6635 <entry> synonym for backslash (<literal>\</literal>) to help reduce the need for backslash
6636 doubling </entry>
6637 </row>
6639 <row>
6640 <entry> <literal>\c</literal><replaceable>X</replaceable> </entry>
6641 <entry> (where <replaceable>X</replaceable> is any character) the character whose
6642 low-order 5 bits are the same as those of
6643 <replaceable>X</replaceable>, and whose other bits are all zero </entry>
6644 </row>
6646 <row>
6647 <entry> <literal>\e</literal> </entry>
6648 <entry> the character whose collating-sequence name
6649 is <literal>ESC</literal>,
6650 or failing that, the character with octal value <literal>033</literal> </entry>
6651 </row>
6653 <row>
6654 <entry> <literal>\f</literal> </entry>
6655 <entry> form feed, as in C </entry>
6656 </row>
6658 <row>
6659 <entry> <literal>\n</literal> </entry>
6660 <entry> newline, as in C </entry>
6661 </row>
6663 <row>
6664 <entry> <literal>\r</literal> </entry>
6665 <entry> carriage return, as in C </entry>
6666 </row>
6668 <row>
6669 <entry> <literal>\t</literal> </entry>
6670 <entry> horizontal tab, as in C </entry>
6671 </row>
6673 <row>
6674 <entry> <literal>\u</literal><replaceable>wxyz</replaceable> </entry>
6675 <entry> (where <replaceable>wxyz</replaceable> is exactly four hexadecimal digits)
6676 the character whose hexadecimal value is
6677 <literal>0x</literal><replaceable>wxyz</replaceable>
6678 </entry>
6679 </row>
6681 <row>
6682 <entry> <literal>\U</literal><replaceable>stuvwxyz</replaceable> </entry>
6683 <entry> (where <replaceable>stuvwxyz</replaceable> is exactly eight hexadecimal
6684 digits)
6685 the character whose hexadecimal value is
6686 <literal>0x</literal><replaceable>stuvwxyz</replaceable>
6687 </entry>
6688 </row>
6690 <row>
6691 <entry> <literal>\v</literal> </entry>
6692 <entry> vertical tab, as in C </entry>
6693 </row>
6695 <row>
6696 <entry> <literal>\x</literal><replaceable>hhh</replaceable> </entry>
6697 <entry> (where <replaceable>hhh</replaceable> is any sequence of hexadecimal
6698 digits)
6699 the character whose hexadecimal value is
6700 <literal>0x</literal><replaceable>hhh</replaceable>
6701 (a single character no matter how many hexadecimal digits are used)
6702 </entry>
6703 </row>
6705 <row>
6706 <entry> <literal>\0</literal> </entry>
6707 <entry> the character whose value is <literal>0</literal> (the null byte)</entry>
6708 </row>
6710 <row>
6711 <entry> <literal>\</literal><replaceable>xy</replaceable> </entry>
6712 <entry> (where <replaceable>xy</replaceable> is exactly two octal digits,
6713 and is not a <firstterm>back reference</firstterm>)
6714 the character whose octal value is
6715 <literal>0</literal><replaceable>xy</replaceable> </entry>
6716 </row>
6718 <row>
6719 <entry> <literal>\</literal><replaceable>xyz</replaceable> </entry>
6720 <entry> (where <replaceable>xyz</replaceable> is exactly three octal digits,
6721 and is not a <firstterm>back reference</firstterm>)
6722 the character whose octal value is
6723 <literal>0</literal><replaceable>xyz</replaceable> </entry>
6724 </row>
6725 </tbody>
6726 </tgroup>
6727 </table>
6729 <para>
6730 Hexadecimal digits are <literal>0</literal>-<literal>9</literal>,
6731 <literal>a</literal>-<literal>f</literal>, and <literal>A</literal>-<literal>F</literal>.
6732 Octal digits are <literal>0</literal>-<literal>7</literal>.
6733 </para>
6735 <para>
6736 Numeric character-entry escapes specifying values outside the ASCII range
6737 (0&ndash;127) have meanings dependent on the database encoding. When the
6738 encoding is UTF-8, escape values are equivalent to Unicode code points,
6739 for example <literal>\u1234</literal> means the character <literal>U+1234</literal>.
6740 For other multibyte encodings, character-entry escapes usually just
6741 specify the concatenation of the byte values for the character. If the
6742 escape value does not correspond to any legal character in the database
6743 encoding, no error will be raised, but it will never match any data.
6744 </para>
6746 <para>
6747 The character-entry escapes are always taken as ordinary characters.
6748 For example, <literal>\135</literal> is <literal>]</literal> in ASCII, but
6749 <literal>\135</literal> does not terminate a bracket expression.
6750 </para>
6752 <table id="posix-class-shorthand-escapes-table">
6753 <title>Regular Expression Class-Shorthand Escapes</title>
6755 <tgroup cols="2">
6756 <thead>
6757 <row>
6758 <entry>Escape</entry>
6759 <entry>Description</entry>
6760 </row>
6761 </thead>
6763 <tbody>
6764 <row>
6765 <entry> <literal>\d</literal> </entry>
6766 <entry> matches any digit, like
6767 <literal>[[:digit:]]</literal> </entry>
6768 </row>
6770 <row>
6771 <entry> <literal>\s</literal> </entry>
6772 <entry> matches any whitespace character, like
6773 <literal>[[:space:]]</literal> </entry>
6774 </row>
6776 <row>
6777 <entry> <literal>\w</literal> </entry>
6778 <entry> matches any word character, like
6779 <literal>[[:word:]]</literal> </entry>
6780 </row>
6782 <row>
6783 <entry> <literal>\D</literal> </entry>
6784 <entry> matches any non-digit, like
6785 <literal>[^[:digit:]]</literal> </entry>
6786 </row>
6788 <row>
6789 <entry> <literal>\S</literal> </entry>
6790 <entry> matches any non-whitespace character, like
6791 <literal>[^[:space:]]</literal> </entry>
6792 </row>
6794 <row>
6795 <entry> <literal>\W</literal> </entry>
6796 <entry> matches any non-word character, like
6797 <literal>[^[:word:]]</literal> </entry>
6798 </row>
6799 </tbody>
6800 </tgroup>
6801 </table>
6803 <para>
6804 The class-shorthand escapes also work within bracket expressions,
6805 although the definitions shown above are not quite syntactically
6806 valid in that context.
6807 For example, <literal>[a-c\d]</literal> is equivalent to
6808 <literal>[a-c[:digit:]]</literal>.
6809 </para>
6811 <table id="posix-constraint-escapes-table">
6812 <title>Regular Expression Constraint Escapes</title>
6814 <tgroup cols="2">
6815 <thead>
6816 <row>
6817 <entry>Escape</entry>
6818 <entry>Description</entry>
6819 </row>
6820 </thead>
6822 <tbody>
6823 <row>
6824 <entry> <literal>\A</literal> </entry>
6825 <entry> matches only at the beginning of the string
6826 (see <xref linkend="posix-matching-rules"/> for how this differs from
6827 <literal>^</literal>) </entry>
6828 </row>
6830 <row>
6831 <entry> <literal>\m</literal> </entry>
6832 <entry> matches only at the beginning of a word </entry>
6833 </row>
6835 <row>
6836 <entry> <literal>\M</literal> </entry>
6837 <entry> matches only at the end of a word </entry>
6838 </row>
6840 <row>
6841 <entry> <literal>\y</literal> </entry>
6842 <entry> matches only at the beginning or end of a word </entry>
6843 </row>
6845 <row>
6846 <entry> <literal>\Y</literal> </entry>
6847 <entry> matches only at a point that is not the beginning or end of a
6848 word </entry>
6849 </row>
6851 <row>
6852 <entry> <literal>\Z</literal> </entry>
6853 <entry> matches only at the end of the string
6854 (see <xref linkend="posix-matching-rules"/> for how this differs from
6855 <literal>$</literal>) </entry>
6856 </row>
6857 </tbody>
6858 </tgroup>
6859 </table>
6861 <para>
6862 A word is defined as in the specification of
6863 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal> above.
6864 Constraint escapes are illegal within bracket expressions.
6865 </para>
6867 <table id="posix-constraint-backref-table">
6868 <title>Regular Expression Back References</title>
6870 <tgroup cols="2">
6871 <thead>
6872 <row>
6873 <entry>Escape</entry>
6874 <entry>Description</entry>
6875 </row>
6876 </thead>
6878 <tbody>
6879 <row>
6880 <entry> <literal>\</literal><replaceable>m</replaceable> </entry>
6881 <entry> (where <replaceable>m</replaceable> is a nonzero digit)
6882 a back reference to the <replaceable>m</replaceable>'th subexpression </entry>
6883 </row>
6885 <row>
6886 <entry> <literal>\</literal><replaceable>mnn</replaceable> </entry>
6887 <entry> (where <replaceable>m</replaceable> is a nonzero digit, and
6888 <replaceable>nn</replaceable> is some more digits, and the decimal value
6889 <replaceable>mnn</replaceable> is not greater than the number of closing capturing
6890 parentheses seen so far)
6891 a back reference to the <replaceable>mnn</replaceable>'th subexpression </entry>
6892 </row>
6893 </tbody>
6894 </tgroup>
6895 </table>
6897 <note>
6898 <para>
6899 There is an inherent ambiguity between octal character-entry
6900 escapes and back references, which is resolved by the following heuristics,
6901 as hinted at above.
6902 A leading zero always indicates an octal escape.
6903 A single non-zero digit, not followed by another digit,
6904 is always taken as a back reference.
6905 A multi-digit sequence not starting with a zero is taken as a back
6906 reference if it comes after a suitable subexpression
6907 (i.e., the number is in the legal range for a back reference),
6908 and otherwise is taken as octal.
6909 </para>
6910 </note>
6911 </sect3>
6913 <sect3 id="posix-metasyntax">
6914 <title>Regular Expression Metasyntax</title>
6916 <para>
6917 In addition to the main syntax described above, there are some special
6918 forms and miscellaneous syntactic facilities available.
6919 </para>
6921 <para>
6922 An RE can begin with one of two special <firstterm>director</firstterm> prefixes.
6923 If an RE begins with <literal>***:</literal>,
6924 the rest of the RE is taken as an ARE. (This normally has no effect in
6925 <productname>PostgreSQL</productname>, since REs are assumed to be AREs;
6926 but it does have an effect if ERE or BRE mode had been specified by
6927 the <replaceable>flags</replaceable> parameter to a regex function.)
6928 If an RE begins with <literal>***=</literal>,
6929 the rest of the RE is taken to be a literal string,
6930 with all characters considered ordinary characters.
6931 </para>
6933 <para>
6934 An ARE can begin with <firstterm>embedded options</firstterm>:
6935 a sequence <literal>(?</literal><replaceable>xyz</replaceable><literal>)</literal>
6936 (where <replaceable>xyz</replaceable> is one or more alphabetic characters)
6937 specifies options affecting the rest of the RE.
6938 These options override any previously determined options &mdash;
6939 in particular, they can override the case-sensitivity behavior implied by
6940 a regex operator, or the <replaceable>flags</replaceable> parameter to a regex
6941 function.
6942 The available option letters are
6943 shown in <xref linkend="posix-embedded-options-table"/>.
6944 Note that these same option letters are used in the <replaceable>flags</replaceable>
6945 parameters of regex functions.
6946 </para>
6948 <table id="posix-embedded-options-table">
6949 <title>ARE Embedded-Option Letters</title>
6951 <tgroup cols="2">
6952 <thead>
6953 <row>
6954 <entry>Option</entry>
6955 <entry>Description</entry>
6956 </row>
6957 </thead>
6959 <tbody>
6960 <row>
6961 <entry> <literal>b</literal> </entry>
6962 <entry> rest of RE is a BRE </entry>
6963 </row>
6965 <row>
6966 <entry> <literal>c</literal> </entry>
6967 <entry> case-sensitive matching (overrides operator type) </entry>
6968 </row>
6970 <row>
6971 <entry> <literal>e</literal> </entry>
6972 <entry> rest of RE is an ERE </entry>
6973 </row>
6975 <row>
6976 <entry> <literal>i</literal> </entry>
6977 <entry> case-insensitive matching (see
6978 <xref linkend="posix-matching-rules"/>) (overrides operator type) </entry>
6979 </row>
6981 <row>
6982 <entry> <literal>m</literal> </entry>
6983 <entry> historical synonym for <literal>n</literal> </entry>
6984 </row>
6986 <row>
6987 <entry> <literal>n</literal> </entry>
6988 <entry> newline-sensitive matching (see
6989 <xref linkend="posix-matching-rules"/>) </entry>
6990 </row>
6992 <row>
6993 <entry> <literal>p</literal> </entry>
6994 <entry> partial newline-sensitive matching (see
6995 <xref linkend="posix-matching-rules"/>) </entry>
6996 </row>
6998 <row>
6999 <entry> <literal>q</literal> </entry>
7000 <entry> rest of RE is a literal (<quote>quoted</quote>) string, all ordinary
7001 characters </entry>
7002 </row>
7004 <row>
7005 <entry> <literal>s</literal> </entry>
7006 <entry> non-newline-sensitive matching (default) </entry>
7007 </row>
7009 <row>
7010 <entry> <literal>t</literal> </entry>
7011 <entry> tight syntax (default; see below) </entry>
7012 </row>
7014 <row>
7015 <entry> <literal>w</literal> </entry>
7016 <entry> inverse partial newline-sensitive (<quote>weird</quote>) matching
7017 (see <xref linkend="posix-matching-rules"/>) </entry>
7018 </row>
7020 <row>
7021 <entry> <literal>x</literal> </entry>
7022 <entry> expanded syntax (see below) </entry>
7023 </row>
7024 </tbody>
7025 </tgroup>
7026 </table>
7028 <para>
7029 Embedded options take effect at the <literal>)</literal> terminating the sequence.
7030 They can appear only at the start of an ARE (after the
7031 <literal>***:</literal> director if any).
7032 </para>
7034 <para>
7035 In addition to the usual (<firstterm>tight</firstterm>) RE syntax, in which all
7036 characters are significant, there is an <firstterm>expanded</firstterm> syntax,
7037 available by specifying the embedded <literal>x</literal> option.
7038 In the expanded syntax,
7039 white-space characters in the RE are ignored, as are
7040 all characters between a <literal>#</literal>
7041 and the following newline (or the end of the RE). This
7042 permits paragraphing and commenting a complex RE.
7043 There are three exceptions to that basic rule:
7045 <itemizedlist>
7046 <listitem>
7047 <para>
7048 a white-space character or <literal>#</literal> preceded by <literal>\</literal> is
7049 retained
7050 </para>
7051 </listitem>
7052 <listitem>
7053 <para>
7054 white space or <literal>#</literal> within a bracket expression is retained
7055 </para>
7056 </listitem>
7057 <listitem>
7058 <para>
7059 white space and comments cannot appear within multi-character symbols,
7060 such as <literal>(?:</literal>
7061 </para>
7062 </listitem>
7063 </itemizedlist>
7065 For this purpose, white-space characters are blank, tab, newline, and
7066 any character that belongs to the <replaceable>space</replaceable> character class.
7067 </para>
7069 <para>
7070 Finally, in an ARE, outside bracket expressions, the sequence
7071 <literal>(?#</literal><replaceable>ttt</replaceable><literal>)</literal>
7072 (where <replaceable>ttt</replaceable> is any text not containing a <literal>)</literal>)
7073 is a comment, completely ignored.
7074 Again, this is not allowed between the characters of
7075 multi-character symbols, like <literal>(?:</literal>.
7076 Such comments are more a historical artifact than a useful facility,
7077 and their use is deprecated; use the expanded syntax instead.
7078 </para>
7080 <para>
7081 <emphasis>None</emphasis> of these metasyntax extensions is available if
7082 an initial <literal>***=</literal> director
7083 has specified that the user's input be treated as a literal string
7084 rather than as an RE.
7085 </para>
7086 </sect3>
7088 <sect3 id="posix-matching-rules">
7089 <title>Regular Expression Matching Rules</title>
7091 <para>
7092 In the event that an RE could match more than one substring of a given
7093 string, the RE matches the one starting earliest in the string.
7094 If the RE could match more than one substring starting at that point,
7095 either the longest possible match or the shortest possible match will
7096 be taken, depending on whether the RE is <firstterm>greedy</firstterm> or
7097 <firstterm>non-greedy</firstterm>.
7098 </para>
7100 <para>
7101 Whether an RE is greedy or not is determined by the following rules:
7102 <itemizedlist>
7103 <listitem>
7104 <para>
7105 Most atoms, and all constraints, have no greediness attribute (because
7106 they cannot match variable amounts of text anyway).
7107 </para>
7108 </listitem>
7109 <listitem>
7110 <para>
7111 Adding parentheses around an RE does not change its greediness.
7112 </para>
7113 </listitem>
7114 <listitem>
7115 <para>
7116 A quantified atom with a fixed-repetition quantifier
7117 (<literal>{</literal><replaceable>m</replaceable><literal>}</literal>
7119 <literal>{</literal><replaceable>m</replaceable><literal>}?</literal>)
7120 has the same greediness (possibly none) as the atom itself.
7121 </para>
7122 </listitem>
7123 <listitem>
7124 <para>
7125 A quantified atom with other normal quantifiers (including
7126 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}</literal>
7127 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7128 is greedy (prefers longest match).
7129 </para>
7130 </listitem>
7131 <listitem>
7132 <para>
7133 A quantified atom with a non-greedy quantifier (including
7134 <literal>{</literal><replaceable>m</replaceable><literal>,</literal><replaceable>n</replaceable><literal>}?</literal>
7135 with <replaceable>m</replaceable> equal to <replaceable>n</replaceable>)
7136 is non-greedy (prefers shortest match).
7137 </para>
7138 </listitem>
7139 <listitem>
7140 <para>
7141 A branch &mdash; that is, an RE that has no top-level
7142 <literal>|</literal> operator &mdash; has the same greediness as the first
7143 quantified atom in it that has a greediness attribute.
7144 </para>
7145 </listitem>
7146 <listitem>
7147 <para>
7148 An RE consisting of two or more branches connected by the
7149 <literal>|</literal> operator is always greedy.
7150 </para>
7151 </listitem>
7152 </itemizedlist>
7153 </para>
7155 <para>
7156 The above rules associate greediness attributes not only with individual
7157 quantified atoms, but with branches and entire REs that contain quantified
7158 atoms. What that means is that the matching is done in such a way that
7159 the branch, or whole RE, matches the longest or shortest possible
7160 substring <emphasis>as a whole</emphasis>. Once the length of the entire match
7161 is determined, the part of it that matches any particular subexpression
7162 is determined on the basis of the greediness attribute of that
7163 subexpression, with subexpressions starting earlier in the RE taking
7164 priority over ones starting later.
7165 </para>
7167 <para>
7168 An example of what this means:
7169 <screen>
7170 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
7171 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
7172 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
7173 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
7174 </screen>
7175 In the first case, the RE as a whole is greedy because <literal>Y*</literal>
7176 is greedy. It can match beginning at the <literal>Y</literal>, and it matches
7177 the longest possible string starting there, i.e., <literal>Y123</literal>.
7178 The output is the parenthesized part of that, or <literal>123</literal>.
7179 In the second case, the RE as a whole is non-greedy because <literal>Y*?</literal>
7180 is non-greedy. It can match beginning at the <literal>Y</literal>, and it matches
7181 the shortest possible string starting there, i.e., <literal>Y1</literal>.
7182 The subexpression <literal>[0-9]{1,3}</literal> is greedy but it cannot change
7183 the decision as to the overall match length; so it is forced to match
7184 just <literal>1</literal>.
7185 </para>
7187 <para>
7188 In short, when an RE contains both greedy and non-greedy subexpressions,
7189 the total match length is either as long as possible or as short as
7190 possible, according to the attribute assigned to the whole RE. The
7191 attributes assigned to the subexpressions only affect how much of that
7192 match they are allowed to <quote>eat</quote> relative to each other.
7193 </para>
7195 <para>
7196 The quantifiers <literal>{1,1}</literal> and <literal>{1,1}?</literal>
7197 can be used to force greediness or non-greediness, respectively,
7198 on a subexpression or a whole RE.
7199 This is useful when you need the whole RE to have a greediness attribute
7200 different from what's deduced from its elements. As an example,
7201 suppose that we are trying to separate a string containing some digits
7202 into the digits and the parts before and after them. We might try to
7203 do that like this:
7204 <screen>
7205 SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
7206 <lineannotation>Result: </lineannotation><computeroutput>{abc0123,4,xyz}</computeroutput>
7207 </screen>
7208 That didn't work: the first <literal>.*</literal> is greedy so
7209 it <quote>eats</quote> as much as it can, leaving the <literal>\d+</literal> to
7210 match at the last possible place, the last digit. We might try to fix
7211 that by making it non-greedy:
7212 <screen>
7213 SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
7214 <lineannotation>Result: </lineannotation><computeroutput>{abc,0,""}</computeroutput>
7215 </screen>
7216 That didn't work either, because now the RE as a whole is non-greedy
7217 and so it ends the overall match as soon as possible. We can get what
7218 we want by forcing the RE as a whole to be greedy:
7219 <screen>
7220 SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){1,1}');
7221 <lineannotation>Result: </lineannotation><computeroutput>{abc,01234,xyz}</computeroutput>
7222 </screen>
7223 Controlling the RE's overall greediness separately from its components'
7224 greediness allows great flexibility in handling variable-length patterns.
7225 </para>
7227 <para>
7228 When deciding what is a longer or shorter match,
7229 match lengths are measured in characters, not collating elements.
7230 An empty string is considered longer than no match at all.
7231 For example:
7232 <literal>bb*</literal>
7233 matches the three middle characters of <literal>abbbc</literal>;
7234 <literal>(week|wee)(night|knights)</literal>
7235 matches all ten characters of <literal>weeknights</literal>;
7236 when <literal>(.*).*</literal>
7237 is matched against <literal>abc</literal> the parenthesized subexpression
7238 matches all three characters; and when
7239 <literal>(a*)*</literal> is matched against <literal>bc</literal>
7240 both the whole RE and the parenthesized
7241 subexpression match an empty string.
7242 </para>
7244 <para>
7245 If case-independent matching is specified,
7246 the effect is much as if all case distinctions had vanished from the
7247 alphabet.
7248 When an alphabetic that exists in multiple cases appears as an
7249 ordinary character outside a bracket expression, it is effectively
7250 transformed into a bracket expression containing both cases,
7251 e.g., <literal>x</literal> becomes <literal>[xX]</literal>.
7252 When it appears inside a bracket expression, all case counterparts
7253 of it are added to the bracket expression, e.g.,
7254 <literal>[x]</literal> becomes <literal>[xX]</literal>
7255 and <literal>[^x]</literal> becomes <literal>[^xX]</literal>.
7256 </para>
7258 <para>
7259 If newline-sensitive matching is specified, <literal>.</literal>
7260 and bracket expressions using <literal>^</literal>
7261 will never match the newline character
7262 (so that matches will not cross lines unless the RE
7263 explicitly includes a newline)
7264 and <literal>^</literal> and <literal>$</literal>
7265 will match the empty string after and before a newline
7266 respectively, in addition to matching at beginning and end of string
7267 respectively.
7268 But the ARE escapes <literal>\A</literal> and <literal>\Z</literal>
7269 continue to match beginning or end of string <emphasis>only</emphasis>.
7270 Also, the character class shorthands <literal>\D</literal>
7271 and <literal>\W</literal> will match a newline regardless of this mode.
7272 (Before <productname>PostgreSQL</productname> 14, they did not match
7273 newlines when in newline-sensitive mode.
7274 Write <literal>[^[:digit:]]</literal>
7275 or <literal>[^[:word:]]</literal> to get the old behavior.)
7276 </para>
7278 <para>
7279 If partial newline-sensitive matching is specified,
7280 this affects <literal>.</literal> and bracket expressions
7281 as with newline-sensitive matching, but not <literal>^</literal>
7282 and <literal>$</literal>.
7283 </para>
7285 <para>
7286 If inverse partial newline-sensitive matching is specified,
7287 this affects <literal>^</literal> and <literal>$</literal>
7288 as with newline-sensitive matching, but not <literal>.</literal>
7289 and bracket expressions.
7290 This isn't very useful but is provided for symmetry.
7291 </para>
7292 </sect3>
7294 <sect3 id="posix-limits-compatibility">
7295 <title>Limits and Compatibility</title>
7297 <para>
7298 No particular limit is imposed on the length of REs in this
7299 implementation. However,
7300 programs intended to be highly portable should not employ REs longer
7301 than 256 bytes,
7302 as a POSIX-compliant implementation can refuse to accept such REs.
7303 </para>
7305 <para>
7306 The only feature of AREs that is actually incompatible with
7307 POSIX EREs is that <literal>\</literal> does not lose its special
7308 significance inside bracket expressions.
7309 All other ARE features use syntax which is illegal or has
7310 undefined or unspecified effects in POSIX EREs;
7311 the <literal>***</literal> syntax of directors likewise is outside the POSIX
7312 syntax for both BREs and EREs.
7313 </para>
7315 <para>
7316 Many of the ARE extensions are borrowed from Perl, but some have
7317 been changed to clean them up, and a few Perl extensions are not present.
7318 Incompatibilities of note include <literal>\b</literal>, <literal>\B</literal>,
7319 the lack of special treatment for a trailing newline,
7320 the addition of complemented bracket expressions to the things
7321 affected by newline-sensitive matching,
7322 the restrictions on parentheses and back references in lookahead/lookbehind
7323 constraints, and the longest/shortest-match (rather than first-match)
7324 matching semantics.
7325 </para>
7326 </sect3>
7328 <sect3 id="posix-basic-regexes">
7329 <title>Basic Regular Expressions</title>
7331 <para>
7332 BREs differ from EREs in several respects.
7333 In BREs, <literal>|</literal>, <literal>+</literal>, and <literal>?</literal>
7334 are ordinary characters and there is no equivalent
7335 for their functionality.
7336 The delimiters for bounds are
7337 <literal>\{</literal> and <literal>\}</literal>,
7338 with <literal>{</literal> and <literal>}</literal>
7339 by themselves ordinary characters.
7340 The parentheses for nested subexpressions are
7341 <literal>\(</literal> and <literal>\)</literal>,
7342 with <literal>(</literal> and <literal>)</literal> by themselves ordinary characters.
7343 <literal>^</literal> is an ordinary character except at the beginning of the
7344 RE or the beginning of a parenthesized subexpression,
7345 <literal>$</literal> is an ordinary character except at the end of the
7346 RE or the end of a parenthesized subexpression,
7347 and <literal>*</literal> is an ordinary character if it appears at the beginning
7348 of the RE or the beginning of a parenthesized subexpression
7349 (after a possible leading <literal>^</literal>).
7350 Finally, single-digit back references are available, and
7351 <literal>\&lt;</literal> and <literal>\&gt;</literal>
7352 are synonyms for
7353 <literal>[[:&lt;:]]</literal> and <literal>[[:&gt;:]]</literal>
7354 respectively; no other escapes are available in BREs.
7355 </para>
7356 </sect3>
7358 <!-- end re_syntax.n man page -->
7360 <sect3 id="posix-vs-xquery">
7361 <title>Differences from SQL Standard and XQuery</title>
7363 <indexterm zone="posix-vs-xquery">
7364 <primary>LIKE_REGEX</primary>
7365 </indexterm>
7367 <indexterm zone="posix-vs-xquery">
7368 <primary>OCCURRENCES_REGEX</primary>
7369 </indexterm>
7371 <indexterm zone="posix-vs-xquery">
7372 <primary>POSITION_REGEX</primary>
7373 </indexterm>
7375 <indexterm zone="posix-vs-xquery">
7376 <primary>SUBSTRING_REGEX</primary>
7377 </indexterm>
7379 <indexterm zone="posix-vs-xquery">
7380 <primary>TRANSLATE_REGEX</primary>
7381 </indexterm>
7383 <indexterm zone="posix-vs-xquery">
7384 <primary>XQuery regular expressions</primary>
7385 </indexterm>
7387 <para>
7388 Since SQL:2008, the SQL standard includes regular expression operators
7389 and functions that performs pattern
7390 matching according to the XQuery regular expression
7391 standard:
7392 <itemizedlist>
7393 <listitem><para><literal>LIKE_REGEX</literal></para></listitem>
7394 <listitem><para><literal>OCCURRENCES_REGEX</literal></para></listitem>
7395 <listitem><para><literal>POSITION_REGEX</literal></para></listitem>
7396 <listitem><para><literal>SUBSTRING_REGEX</literal></para></listitem>
7397 <listitem><para><literal>TRANSLATE_REGEX</literal></para></listitem>
7398 </itemizedlist>
7399 <productname>PostgreSQL</productname> does not currently implement these
7400 operators and functions. You can get approximately equivalent
7401 functionality in each case as shown in <xref
7402 linkend="functions-regexp-sql-table"/>. (Various optional clauses on
7403 both sides have been omitted in this table.)
7404 </para>
7406 <table id="functions-regexp-sql-table">
7407 <title>Regular Expression Functions Equivalencies</title>
7409 <tgroup cols="2">
7410 <thead>
7411 <row>
7412 <entry>SQL standard</entry>
7413 <entry>PostgreSQL</entry>
7414 </row>
7415 </thead>
7417 <tbody>
7418 <row>
7419 <entry><literal><replaceable>string</replaceable> LIKE_REGEX <replaceable>pattern</replaceable></literal></entry>
7420 <entry><literal>regexp_like(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal> or <literal><replaceable>string</replaceable> ~ <replaceable>pattern</replaceable></literal></entry>
7421 </row>
7423 <row>
7424 <entry><literal>OCCURRENCES_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7425 <entry><literal>regexp_count(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7426 </row>
7428 <row>
7429 <entry><literal>POSITION_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7430 <entry><literal>regexp_instr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7431 </row>
7433 <row>
7434 <entry><literal>SUBSTRING_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable>)</literal></entry>
7435 <entry><literal>regexp_substr(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>)</literal></entry>
7436 </row>
7438 <row>
7439 <entry><literal>TRANSLATE_REGEX(<replaceable>pattern</replaceable> IN <replaceable>string</replaceable> WITH <replaceable>replacement</replaceable>)</literal></entry>
7440 <entry><literal>regexp_replace(<replaceable>string</replaceable>, <replaceable>pattern</replaceable>, <replaceable>replacement</replaceable>)</literal></entry>
7441 </row>
7442 </tbody>
7443 </tgroup>
7444 </table>
7446 <para>
7447 Regular expression functions similar to those provided by PostgreSQL are
7448 also available in a number of other SQL implementations, whereas the
7449 SQL-standard functions are not as widely implemented. Some of the
7450 details of the regular expression syntax will likely differ in each
7451 implementation.
7452 </para>
7454 <para>
7455 The SQL-standard operators and functions use XQuery regular expressions,
7456 which are quite close to the ARE syntax described above.
7457 Notable differences between the existing POSIX-based
7458 regular-expression feature and XQuery regular expressions include:
7460 <itemizedlist>
7461 <listitem>
7462 <para>
7463 XQuery character class subtraction is not supported. An example of
7464 this feature is using the following to match only English
7465 consonants: <literal>[a-z-[aeiou]]</literal>.
7466 </para>
7467 </listitem>
7468 <listitem>
7469 <para>
7470 XQuery character class shorthands <literal>\c</literal>,
7471 <literal>\C</literal>, <literal>\i</literal>,
7472 and <literal>\I</literal> are not supported.
7473 </para>
7474 </listitem>
7475 <listitem>
7476 <para>
7477 XQuery character class elements
7478 using <literal>\p{UnicodeProperty}</literal> or the
7479 inverse <literal>\P{UnicodeProperty}</literal> are not supported.
7480 </para>
7481 </listitem>
7482 <listitem>
7483 <para>
7484 POSIX interprets character classes such as <literal>\w</literal>
7485 (see <xref linkend="posix-class-shorthand-escapes-table"/>)
7486 according to the prevailing locale (which you can control by
7487 attaching a <literal>COLLATE</literal> clause to the operator or
7488 function). XQuery specifies these classes by reference to Unicode
7489 character properties, so equivalent behavior is obtained only with
7490 a locale that follows the Unicode rules.
7491 </para>
7492 </listitem>
7493 <listitem>
7494 <para>
7495 The SQL standard (not XQuery itself) attempts to cater for more
7496 variants of <quote>newline</quote> than POSIX does. The
7497 newline-sensitive matching options described above consider only
7498 ASCII NL (<literal>\n</literal>) to be a newline, but SQL would have
7499 us treat CR (<literal>\r</literal>), CRLF (<literal>\r\n</literal>)
7500 (a Windows-style newline), and some Unicode-only characters like
7501 LINE SEPARATOR (U+2028) as newlines as well.
7502 Notably, <literal>.</literal> and <literal>\s</literal> should
7503 count <literal>\r\n</literal> as one character not two according to
7504 SQL.
7505 </para>
7506 </listitem>
7507 <listitem>
7508 <para>
7509 Of the character-entry escapes described in
7510 <xref linkend="posix-character-entry-escapes-table"/>,
7511 XQuery supports only <literal>\n</literal>, <literal>\r</literal>,
7512 and <literal>\t</literal>.
7513 </para>
7514 </listitem>
7515 <listitem>
7516 <para>
7517 XQuery does not support
7518 the <literal>[:<replaceable>name</replaceable>:]</literal> syntax
7519 for character classes within bracket expressions.
7520 </para>
7521 </listitem>
7522 <listitem>
7523 <para>
7524 XQuery does not have lookahead or lookbehind constraints,
7525 nor any of the constraint escapes described in
7526 <xref linkend="posix-constraint-escapes-table"/>.
7527 </para>
7528 </listitem>
7529 <listitem>
7530 <para>
7531 The metasyntax forms described in <xref linkend="posix-metasyntax"/>
7532 do not exist in XQuery.
7533 </para>
7534 </listitem>
7535 <listitem>
7536 <para>
7537 The regular expression flag letters defined by XQuery are
7538 related to but not the same as the option letters for POSIX
7539 (<xref linkend="posix-embedded-options-table"/>). While the
7540 <literal>i</literal> and <literal>q</literal> options behave the
7541 same, others do not:
7542 <itemizedlist>
7543 <listitem>
7544 <para>
7545 XQuery's <literal>s</literal> (allow dot to match newline)
7546 and <literal>m</literal> (allow <literal>^</literal>
7547 and <literal>$</literal> to match at newlines) flags provide
7548 access to the same behaviors as
7549 POSIX's <literal>n</literal>, <literal>p</literal>
7550 and <literal>w</literal> flags, but they
7551 do <emphasis>not</emphasis> match the behavior of
7552 POSIX's <literal>s</literal> and <literal>m</literal> flags.
7553 Note in particular that dot-matches-newline is the default
7554 behavior in POSIX but not XQuery.
7555 </para>
7556 </listitem>
7557 <listitem>
7558 <para>
7559 XQuery's <literal>x</literal> (ignore whitespace in pattern) flag
7560 is noticeably different from POSIX's expanded-mode flag.
7561 POSIX's <literal>x</literal> flag also
7562 allows <literal>#</literal> to begin a comment in the pattern,
7563 and POSIX will not ignore a whitespace character after a
7564 backslash.
7565 </para>
7566 </listitem>
7567 </itemizedlist>
7568 </para>
7569 </listitem>
7570 </itemizedlist>
7571 </para>
7573 </sect3>
7574 </sect2>
7575 </sect1>
7578 <sect1 id="functions-formatting">
7579 <title>Data Type Formatting Functions</title>
7581 <indexterm>
7582 <primary>formatting</primary>
7583 </indexterm>
7585 <para>
7586 The <productname>PostgreSQL</productname> formatting functions
7587 provide a powerful set of tools for converting various data types
7588 (date/time, integer, floating point, numeric) to formatted strings
7589 and for converting from formatted strings to specific data types.
7590 <xref linkend="functions-formatting-table"/> lists them.
7591 These functions all follow a common calling convention: the first
7592 argument is the value to be formatted and the second argument is a
7593 template that defines the output or input format.
7594 </para>
7596 <table id="functions-formatting-table">
7597 <title>Formatting Functions</title>
7598 <tgroup cols="1">
7599 <thead>
7600 <row>
7601 <entry role="func_table_entry"><para role="func_signature">
7602 Function
7603 </para>
7604 <para>
7605 Description
7606 </para>
7607 <para>
7608 Example(s)
7609 </para></entry>
7610 </row>
7611 </thead>
7613 <tbody>
7614 <row>
7615 <entry role="func_table_entry"><para role="func_signature">
7616 <indexterm>
7617 <primary>to_char</primary>
7618 </indexterm>
7619 <function>to_char</function> ( <type>timestamp</type>, <type>text</type> )
7620 <returnvalue>text</returnvalue>
7621 </para>
7622 <para role="func_signature">
7623 <function>to_char</function> ( <type>timestamp with time zone</type>, <type>text</type> )
7624 <returnvalue>text</returnvalue>
7625 </para>
7626 <para>
7627 Converts time stamp to string according to the given format.
7628 </para>
7629 <para>
7630 <literal>to_char(timestamp '2002-04-20 17:31:12.66', 'HH12:MI:SS')</literal>
7631 <returnvalue>05:31:12</returnvalue>
7632 </para></entry>
7633 </row>
7635 <row>
7636 <entry role="func_table_entry"><para role="func_signature">
7637 <function>to_char</function> ( <type>interval</type>, <type>text</type> )
7638 <returnvalue>text</returnvalue>
7639 </para>
7640 <para>
7641 Converts interval to string according to the given format.
7642 </para>
7643 <para>
7644 <literal>to_char(interval '15h 2m 12s', 'HH24:MI:SS')</literal>
7645 <returnvalue>15:02:12</returnvalue>
7646 </para></entry>
7647 </row>
7649 <row>
7650 <entry role="func_table_entry"><para role="func_signature">
7651 <function>to_char</function> ( <replaceable>numeric_type</replaceable>, <type>text</type> )
7652 <returnvalue>text</returnvalue>
7653 </para>
7654 <para>
7655 Converts number to string according to the given format; available
7656 for <type>integer</type>, <type>bigint</type>, <type>numeric</type>,
7657 <type>real</type>, <type>double precision</type>.
7658 </para>
7659 <para>
7660 <literal>to_char(125, '999')</literal>
7661 <returnvalue>125</returnvalue>
7662 </para>
7663 <para>
7664 <literal>to_char(125.8::real, '999D9')</literal>
7665 <returnvalue>125.8</returnvalue>
7666 </para>
7667 <para>
7668 <literal>to_char(-125.8, '999D99S')</literal>
7669 <returnvalue>125.80-</returnvalue>
7670 </para></entry>
7671 </row>
7673 <row>
7674 <entry role="func_table_entry"><para role="func_signature">
7675 <indexterm>
7676 <primary>to_date</primary>
7677 </indexterm>
7678 <function>to_date</function> ( <type>text</type>, <type>text</type> )
7679 <returnvalue>date</returnvalue>
7680 </para>
7681 <para>
7682 Converts string to date according to the given format.
7683 </para>
7684 <para>
7685 <literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal>
7686 <returnvalue>2000-12-05</returnvalue>
7687 </para></entry>
7688 </row>
7690 <row>
7691 <entry role="func_table_entry"><para role="func_signature">
7692 <indexterm>
7693 <primary>to_number</primary>
7694 </indexterm>
7695 <function>to_number</function> ( <type>text</type>, <type>text</type> )
7696 <returnvalue>numeric</returnvalue>
7697 </para>
7698 <para>
7699 Converts string to numeric according to the given format.
7700 </para>
7701 <para>
7702 <literal>to_number('12,454.8-', '99G999D9S')</literal>
7703 <returnvalue>-12454.8</returnvalue>
7704 </para></entry>
7705 </row>
7707 <row>
7708 <entry role="func_table_entry"><para role="func_signature">
7709 <indexterm>
7710 <primary>to_timestamp</primary>
7711 </indexterm>
7712 <function>to_timestamp</function> ( <type>text</type>, <type>text</type> )
7713 <returnvalue>timestamp with time zone</returnvalue>
7714 </para>
7715 <para>
7716 Converts string to time stamp according to the given format.
7717 (See also <function>to_timestamp(double precision)</function> in
7718 <xref linkend="functions-datetime-table"/>.)
7719 </para>
7720 <para>
7721 <literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal>
7722 <returnvalue>2000-12-05 00:00:00-05</returnvalue>
7723 </para></entry>
7724 </row>
7725 </tbody>
7726 </tgroup>
7727 </table>
7729 <tip>
7730 <para>
7731 <function>to_timestamp</function> and <function>to_date</function>
7732 exist to handle input formats that cannot be converted by
7733 simple casting. For most standard date/time formats, simply casting the
7734 source string to the required data type works, and is much easier.
7735 Similarly, <function>to_number</function> is unnecessary for standard numeric
7736 representations.
7737 </para>
7738 </tip>
7740 <para>
7741 In a <function>to_char</function> output template string, there are certain
7742 patterns that are recognized and replaced with appropriately-formatted
7743 data based on the given value. Any text that is not a template pattern is
7744 simply copied verbatim. Similarly, in an input template string (for the
7745 other functions), template patterns identify the values to be supplied by
7746 the input data string. If there are characters in the template string
7747 that are not template patterns, the corresponding characters in the input
7748 data string are simply skipped over (whether or not they are equal to the
7749 template string characters).
7750 </para>
7752 <para>
7753 <xref linkend="functions-formatting-datetime-table"/> shows the
7754 template patterns available for formatting date and time values.
7755 </para>
7757 <table id="functions-formatting-datetime-table">
7758 <title>Template Patterns for Date/Time Formatting</title>
7759 <tgroup cols="2">
7760 <thead>
7761 <row>
7762 <entry>Pattern</entry>
7763 <entry>Description</entry>
7764 </row>
7765 </thead>
7766 <tbody>
7767 <row>
7768 <entry><literal>HH</literal></entry>
7769 <entry>hour of day (01&ndash;12)</entry>
7770 </row>
7771 <row>
7772 <entry><literal>HH12</literal></entry>
7773 <entry>hour of day (01&ndash;12)</entry>
7774 </row>
7775 <row>
7776 <entry><literal>HH24</literal></entry>
7777 <entry>hour of day (00&ndash;23)</entry>
7778 </row>
7779 <row>
7780 <entry><literal>MI</literal></entry>
7781 <entry>minute (00&ndash;59)</entry>
7782 </row>
7783 <row>
7784 <entry><literal>SS</literal></entry>
7785 <entry>second (00&ndash;59)</entry>
7786 </row>
7787 <row>
7788 <entry><literal>MS</literal></entry>
7789 <entry>millisecond (000&ndash;999)</entry>
7790 </row>
7791 <row>
7792 <entry><literal>US</literal></entry>
7793 <entry>microsecond (000000&ndash;999999)</entry>
7794 </row>
7795 <row>
7796 <entry><literal>FF1</literal></entry>
7797 <entry>tenth of second (0&ndash;9)</entry>
7798 </row>
7799 <row>
7800 <entry><literal>FF2</literal></entry>
7801 <entry>hundredth of second (00&ndash;99)</entry>
7802 </row>
7803 <row>
7804 <entry><literal>FF3</literal></entry>
7805 <entry>millisecond (000&ndash;999)</entry>
7806 </row>
7807 <row>
7808 <entry><literal>FF4</literal></entry>
7809 <entry>tenth of a millisecond (0000&ndash;9999)</entry>
7810 </row>
7811 <row>
7812 <entry><literal>FF5</literal></entry>
7813 <entry>hundredth of a millisecond (00000&ndash;99999)</entry>
7814 </row>
7815 <row>
7816 <entry><literal>FF6</literal></entry>
7817 <entry>microsecond (000000&ndash;999999)</entry>
7818 </row>
7819 <row>
7820 <entry><literal>SSSS</literal>, <literal>SSSSS</literal></entry>
7821 <entry>seconds past midnight (0&ndash;86399)</entry>
7822 </row>
7823 <row>
7824 <entry><literal>AM</literal>, <literal>am</literal>,
7825 <literal>PM</literal> or <literal>pm</literal></entry>
7826 <entry>meridiem indicator (without periods)</entry>
7827 </row>
7828 <row>
7829 <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
7830 <literal>P.M.</literal> or <literal>p.m.</literal></entry>
7831 <entry>meridiem indicator (with periods)</entry>
7832 </row>
7833 <row>
7834 <entry><literal>Y,YYY</literal></entry>
7835 <entry>year (4 or more digits) with comma</entry>
7836 </row>
7837 <row>
7838 <entry><literal>YYYY</literal></entry>
7839 <entry>year (4 or more digits)</entry>
7840 </row>
7841 <row>
7842 <entry><literal>YYY</literal></entry>
7843 <entry>last 3 digits of year</entry>
7844 </row>
7845 <row>
7846 <entry><literal>YY</literal></entry>
7847 <entry>last 2 digits of year</entry>
7848 </row>
7849 <row>
7850 <entry><literal>Y</literal></entry>
7851 <entry>last digit of year</entry>
7852 </row>
7853 <row>
7854 <entry><literal>IYYY</literal></entry>
7855 <entry>ISO 8601 week-numbering year (4 or more digits)</entry>
7856 </row>
7857 <row>
7858 <entry><literal>IYY</literal></entry>
7859 <entry>last 3 digits of ISO 8601 week-numbering year</entry>
7860 </row>
7861 <row>
7862 <entry><literal>IY</literal></entry>
7863 <entry>last 2 digits of ISO 8601 week-numbering year</entry>
7864 </row>
7865 <row>
7866 <entry><literal>I</literal></entry>
7867 <entry>last digit of ISO 8601 week-numbering year</entry>
7868 </row>
7869 <row>
7870 <entry><literal>BC</literal>, <literal>bc</literal>,
7871 <literal>AD</literal> or <literal>ad</literal></entry>
7872 <entry>era indicator (without periods)</entry>
7873 </row>
7874 <row>
7875 <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
7876 <literal>A.D.</literal> or <literal>a.d.</literal></entry>
7877 <entry>era indicator (with periods)</entry>
7878 </row>
7879 <row>
7880 <entry><literal>MONTH</literal></entry>
7881 <entry>full upper case month name (blank-padded to 9 chars)</entry>
7882 </row>
7883 <row>
7884 <entry><literal>Month</literal></entry>
7885 <entry>full capitalized month name (blank-padded to 9 chars)</entry>
7886 </row>
7887 <row>
7888 <entry><literal>month</literal></entry>
7889 <entry>full lower case month name (blank-padded to 9 chars)</entry>
7890 </row>
7891 <row>
7892 <entry><literal>MON</literal></entry>
7893 <entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
7894 </row>
7895 <row>
7896 <entry><literal>Mon</literal></entry>
7897 <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
7898 </row>
7899 <row>
7900 <entry><literal>mon</literal></entry>
7901 <entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
7902 </row>
7903 <row>
7904 <entry><literal>MM</literal></entry>
7905 <entry>month number (01&ndash;12)</entry>
7906 </row>
7907 <row>
7908 <entry><literal>DAY</literal></entry>
7909 <entry>full upper case day name (blank-padded to 9 chars)</entry>
7910 </row>
7911 <row>
7912 <entry><literal>Day</literal></entry>
7913 <entry>full capitalized day name (blank-padded to 9 chars)</entry>
7914 </row>
7915 <row>
7916 <entry><literal>day</literal></entry>
7917 <entry>full lower case day name (blank-padded to 9 chars)</entry>
7918 </row>
7919 <row>
7920 <entry><literal>DY</literal></entry>
7921 <entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
7922 </row>
7923 <row>
7924 <entry><literal>Dy</literal></entry>
7925 <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
7926 </row>
7927 <row>
7928 <entry><literal>dy</literal></entry>
7929 <entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
7930 </row>
7931 <row>
7932 <entry><literal>DDD</literal></entry>
7933 <entry>day of year (001&ndash;366)</entry>
7934 </row>
7935 <row>
7936 <entry><literal>IDDD</literal></entry>
7937 <entry>day of ISO 8601 week-numbering year (001&ndash;371; day 1 of the year is Monday of the first ISO week)</entry>
7938 </row>
7939 <row>
7940 <entry><literal>DD</literal></entry>
7941 <entry>day of month (01&ndash;31)</entry>
7942 </row>
7943 <row>
7944 <entry><literal>D</literal></entry>
7945 <entry>day of the week, Sunday (<literal>1</literal>) to Saturday (<literal>7</literal>)</entry>
7946 </row>
7947 <row>
7948 <entry><literal>ID</literal></entry>
7949 <entry>ISO 8601 day of the week, Monday (<literal>1</literal>) to Sunday (<literal>7</literal>)</entry>
7950 </row>
7951 <row>
7952 <entry><literal>W</literal></entry>
7953 <entry>week of month (1&ndash;5) (the first week starts on the first day of the month)</entry>
7954 </row>
7955 <row>
7956 <entry><literal>WW</literal></entry>
7957 <entry>week number of year (1&ndash;53) (the first week starts on the first day of the year)</entry>
7958 </row>
7959 <row>
7960 <entry><literal>IW</literal></entry>
7961 <entry>week number of ISO 8601 week-numbering year (01&ndash;53; the first Thursday of the year is in week 1)</entry>
7962 </row>
7963 <row>
7964 <entry><literal>CC</literal></entry>
7965 <entry>century (2 digits) (the twenty-first century starts on 2001-01-01)</entry>
7966 </row>
7967 <row>
7968 <entry><literal>J</literal></entry>
7969 <entry>Julian Date (integer days since November 24, 4714 BC at local
7970 midnight; see <xref linkend="datetime-julian-dates"/>)</entry>
7971 </row>
7972 <row>
7973 <entry><literal>Q</literal></entry>
7974 <entry>quarter</entry>
7975 </row>
7976 <row>
7977 <entry><literal>RM</literal></entry>
7978 <entry>month in upper case Roman numerals (I&ndash;XII; I=January)</entry>
7979 </row>
7980 <row>
7981 <entry><literal>rm</literal></entry>
7982 <entry>month in lower case Roman numerals (i&ndash;xii; i=January)</entry>
7983 </row>
7984 <row>
7985 <entry><literal>TZ</literal></entry>
7986 <entry>upper case time-zone abbreviation
7987 (only supported in <function>to_char</function>)</entry>
7988 </row>
7989 <row>
7990 <entry><literal>tz</literal></entry>
7991 <entry>lower case time-zone abbreviation
7992 (only supported in <function>to_char</function>)</entry>
7993 </row>
7994 <row>
7995 <entry><literal>TZH</literal></entry>
7996 <entry>time-zone hours</entry>
7997 </row>
7998 <row>
7999 <entry><literal>TZM</literal></entry>
8000 <entry>time-zone minutes</entry>
8001 </row>
8002 <row>
8003 <entry><literal>OF</literal></entry>
8004 <entry>time-zone offset from UTC
8005 (only supported in <function>to_char</function>)</entry>
8006 </row>
8007 </tbody>
8008 </tgroup>
8009 </table>
8011 <para>
8012 Modifiers can be applied to any template pattern to alter its
8013 behavior. For example, <literal>FMMonth</literal>
8014 is the <literal>Month</literal> pattern with the
8015 <literal>FM</literal> modifier.
8016 <xref linkend="functions-formatting-datetimemod-table"/> shows the
8017 modifier patterns for date/time formatting.
8018 </para>
8020 <table id="functions-formatting-datetimemod-table">
8021 <title>Template Pattern Modifiers for Date/Time Formatting</title>
8022 <tgroup cols="3">
8023 <thead>
8024 <row>
8025 <entry>Modifier</entry>
8026 <entry>Description</entry>
8027 <entry>Example</entry>
8028 </row>
8029 </thead>
8030 <tbody>
8031 <row>
8032 <entry><literal>FM</literal> prefix</entry>
8033 <entry>fill mode (suppress leading zeroes and padding blanks)</entry>
8034 <entry><literal>FMMonth</literal></entry>
8035 </row>
8036 <row>
8037 <entry><literal>TH</literal> suffix</entry>
8038 <entry>upper case ordinal number suffix</entry>
8039 <entry><literal>DDTH</literal>, e.g., <literal>12TH</literal></entry>
8040 </row>
8041 <row>
8042 <entry><literal>th</literal> suffix</entry>
8043 <entry>lower case ordinal number suffix</entry>
8044 <entry><literal>DDth</literal>, e.g., <literal>12th</literal></entry>
8045 </row>
8046 <row>
8047 <entry><literal>FX</literal> prefix</entry>
8048 <entry>fixed format global option (see usage notes)</entry>
8049 <entry><literal>FX&nbsp;Month&nbsp;DD&nbsp;Day</literal></entry>
8050 </row>
8051 <row>
8052 <entry><literal>TM</literal> prefix</entry>
8053 <entry>translation mode (use localized day and month names based on
8054 <xref linkend="guc-lc-time"/>)</entry>
8055 <entry><literal>TMMonth</literal></entry>
8056 </row>
8057 <row>
8058 <entry><literal>SP</literal> suffix</entry>
8059 <entry>spell mode (not implemented)</entry>
8060 <entry><literal>DDSP</literal></entry>
8061 </row>
8062 </tbody>
8063 </tgroup>
8064 </table>
8066 <para>
8067 Usage notes for date/time formatting:
8069 <itemizedlist>
8070 <listitem>
8071 <para>
8072 <literal>FM</literal> suppresses leading zeroes and trailing blanks
8073 that would otherwise be added to make the output of a pattern be
8074 fixed-width. In <productname>PostgreSQL</productname>,
8075 <literal>FM</literal> modifies only the next specification, while in
8076 Oracle <literal>FM</literal> affects all subsequent
8077 specifications, and repeated <literal>FM</literal> modifiers
8078 toggle fill mode on and off.
8079 </para>
8080 </listitem>
8082 <listitem>
8083 <para>
8084 <literal>TM</literal> suppresses trailing blanks whether or
8085 not <literal>FM</literal> is specified.
8086 </para>
8087 </listitem>
8089 <listitem>
8090 <para>
8091 <function>to_timestamp</function> and <function>to_date</function>
8092 ignore letter case in the input; so for
8093 example <literal>MON</literal>, <literal>Mon</literal>,
8094 and <literal>mon</literal> all accept the same strings. When using
8095 the <literal>TM</literal> modifier, case-folding is done according to
8096 the rules of the function's input collation (see
8097 <xref linkend="collation"/>).
8098 </para>
8099 </listitem>
8101 <listitem>
8102 <para>
8103 <function>to_timestamp</function> and <function>to_date</function>
8104 skip multiple blank spaces at the beginning of the input string and
8105 around date and time values unless the <literal>FX</literal> option is used. For example,
8106 <literal>to_timestamp('&nbsp;2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'YYYY MON')</literal> and
8107 <literal>to_timestamp('2000 - JUN', 'YYYY-MON')</literal> work, but
8108 <literal>to_timestamp('2000&nbsp;&nbsp;&nbsp;&nbsp;JUN', 'FXYYYY MON')</literal> returns an error
8109 because <function>to_timestamp</function> expects only a single space.
8110 <literal>FX</literal> must be specified as the first item in
8111 the template.
8112 </para>
8113 </listitem>
8115 <listitem>
8116 <para>
8117 A separator (a space or non-letter/non-digit character) in the template string of
8118 <function>to_timestamp</function> and <function>to_date</function>
8119 matches any single separator in the input string or is skipped,
8120 unless the <literal>FX</literal> option is used.
8121 For example, <literal>to_timestamp('2000JUN', 'YYYY///MON')</literal> and
8122 <literal>to_timestamp('2000/JUN', 'YYYY MON')</literal> work, but
8123 <literal>to_timestamp('2000//JUN', 'YYYY/MON')</literal>
8124 returns an error because the number of separators in the input string
8125 exceeds the number of separators in the template.
8126 </para>
8127 <para>
8128 If <literal>FX</literal> is specified, a separator in the template string
8129 matches exactly one character in the input string. But note that the
8130 input string character is not required to be the same as the separator from the template string.
8131 For example, <literal>to_timestamp('2000/JUN', 'FXYYYY MON')</literal>
8132 works, but <literal>to_timestamp('2000/JUN', 'FXYYYY&nbsp;&nbsp;MON')</literal>
8133 returns an error because the second space in the template string consumes
8134 the letter <literal>J</literal> from the input string.
8135 </para>
8136 </listitem>
8138 <listitem>
8139 <para>
8140 A <literal>TZH</literal> template pattern can match a signed number.
8141 Without the <literal>FX</literal> option, minus signs may be ambiguous,
8142 and could be interpreted as a separator.
8143 This ambiguity is resolved as follows: If the number of separators before
8144 <literal>TZH</literal> in the template string is less than the number of
8145 separators before the minus sign in the input string, the minus sign
8146 is interpreted as part of <literal>TZH</literal>.
8147 Otherwise, the minus sign is considered to be a separator between values.
8148 For example, <literal>to_timestamp('2000 -10', 'YYYY TZH')</literal> matches
8149 <literal>-10</literal> to <literal>TZH</literal>, but
8150 <literal>to_timestamp('2000 -10', 'YYYY&nbsp;&nbsp;TZH')</literal>
8151 matches <literal>10</literal> to <literal>TZH</literal>.
8152 </para>
8153 </listitem>
8155 <listitem>
8156 <para>
8157 Ordinary text is allowed in <function>to_char</function>
8158 templates and will be output literally. You can put a substring
8159 in double quotes to force it to be interpreted as literal text
8160 even if it contains template patterns. For example, in
8161 <literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
8162 will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
8163 will not be.
8164 In <function>to_date</function>, <function>to_number</function>,
8165 and <function>to_timestamp</function>, literal text and double-quoted
8166 strings result in skipping the number of characters contained in the
8167 string; for example <literal>"XX"</literal> skips two input characters
8168 (whether or not they are <literal>XX</literal>).
8169 </para>
8170 <tip>
8171 <para>
8172 Prior to <productname>PostgreSQL</productname> 12, it was possible to
8173 skip arbitrary text in the input string using non-letter or non-digit
8174 characters. For example,
8175 <literal>to_timestamp('2000y6m1d', 'yyyy-MM-DD')</literal> used to
8176 work. Now you can only use letter characters for this purpose. For example,
8177 <literal>to_timestamp('2000y6m1d', 'yyyytMMtDDt')</literal> and
8178 <literal>to_timestamp('2000y6m1d', 'yyyy"y"MM"m"DD"d"')</literal>
8179 skip <literal>y</literal>, <literal>m</literal>, and
8180 <literal>d</literal>.
8181 </para>
8182 </tip>
8183 </listitem>
8185 <listitem>
8186 <para>
8187 If you want to have a double quote in the output you must
8188 precede it with a backslash, for example <literal>'\"YYYY
8189 Month\"'</literal>. <!-- "" font-lock sanity :-) -->
8190 Backslashes are not otherwise special outside of double-quoted
8191 strings. Within a double-quoted string, a backslash causes the
8192 next character to be taken literally, whatever it is (but this
8193 has no special effect unless the next character is a double quote
8194 or another backslash).
8195 </para>
8196 </listitem>
8198 <listitem>
8199 <para>
8200 In <function>to_timestamp</function> and <function>to_date</function>,
8201 if the year format specification is less than four digits, e.g.,
8202 <literal>YYY</literal>, and the supplied year is less than four digits,
8203 the year will be adjusted to be nearest to the year 2020, e.g.,
8204 <literal>95</literal> becomes 1995.
8205 </para>
8206 </listitem>
8208 <listitem>
8209 <para>
8210 In <function>to_timestamp</function> and <function>to_date</function>,
8211 negative years are treated as signifying BC. If you write both a
8212 negative year and an explicit <literal>BC</literal> field, you get AD
8213 again. An input of year zero is treated as 1 BC.
8214 </para>
8215 </listitem>
8217 <listitem>
8218 <para>
8219 In <function>to_timestamp</function> and <function>to_date</function>,
8220 the <literal>YYYY</literal> conversion has a restriction when
8221 processing years with more than 4 digits. You must
8222 use some non-digit character or template after <literal>YYYY</literal>,
8223 otherwise the year is always interpreted as 4 digits. For example
8224 (with the year 20000):
8225 <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
8226 interpreted as a 4-digit year; instead use a non-digit
8227 separator after the year, like
8228 <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
8229 <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
8230 </para>
8231 </listitem>
8233 <listitem>
8234 <para>
8235 In <function>to_timestamp</function> and <function>to_date</function>,
8236 the <literal>CC</literal> (century) field is accepted but ignored
8237 if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
8238 <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
8239 <literal>YY</literal> or <literal>Y</literal> then the result is
8240 computed as that year in the specified century. If the century is
8241 specified but the year is not, the first year of the century
8242 is assumed.
8243 </para>
8244 </listitem>
8246 <listitem>
8247 <para>
8248 In <function>to_timestamp</function> and <function>to_date</function>,
8249 weekday names or numbers (<literal>DAY</literal>, <literal>D</literal>,
8250 and related field types) are accepted but are ignored for purposes of
8251 computing the result. The same is true for quarter
8252 (<literal>Q</literal>) fields.
8253 </para>
8254 </listitem>
8256 <listitem>
8257 <para>
8258 In <function>to_timestamp</function> and <function>to_date</function>,
8259 an ISO 8601 week-numbering date (as distinct from a Gregorian date)
8260 can be specified in one of two ways:
8261 <itemizedlist>
8262 <listitem>
8263 <para>
8264 Year, week number, and weekday: for
8265 example <literal>to_date('2006-42-4', 'IYYY-IW-ID')</literal>
8266 returns the date <literal>2006-10-19</literal>.
8267 If you omit the weekday it is assumed to be 1 (Monday).
8268 </para>
8269 </listitem>
8270 <listitem>
8271 <para>
8272 Year and day of year: for example <literal>to_date('2006-291',
8273 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
8274 </para>
8275 </listitem>
8276 </itemizedlist>
8277 </para>
8278 <para>
8279 Attempting to enter a date using a mixture of ISO 8601 week-numbering
8280 fields and Gregorian date fields is nonsensical, and will cause an
8281 error. In the context of an ISO 8601 week-numbering year, the
8282 concept of a <quote>month</quote> or <quote>day of month</quote> has no
8283 meaning. In the context of a Gregorian year, the ISO week has no
8284 meaning.
8285 </para>
8286 <caution>
8287 <para>
8288 While <function>to_date</function> will reject a mixture of
8289 Gregorian and ISO week-numbering date
8290 fields, <function>to_char</function> will not, since output format
8291 specifications like <literal>YYYY-MM-DD (IYYY-IDDD)</literal> can be
8292 useful. But avoid writing something like <literal>IYYY-MM-DD</literal>;
8293 that would yield surprising results near the start of the year.
8294 (See <xref linkend="functions-datetime-extract"/> for more
8295 information.)
8296 </para>
8297 </caution>
8298 </listitem>
8300 <listitem>
8301 <para>
8302 In <function>to_timestamp</function>, millisecond
8303 (<literal>MS</literal>) or microsecond (<literal>US</literal>)
8304 fields are used as the
8305 seconds digits after the decimal point. For example
8306 <literal>to_timestamp('12.3', 'SS.MS')</literal> is not 3 milliseconds,
8307 but 300, because the conversion treats it as 12 + 0.3 seconds.
8308 So, for the format <literal>SS.MS</literal>, the input values
8309 <literal>12.3</literal>, <literal>12.30</literal>,
8310 and <literal>12.300</literal> specify the
8311 same number of milliseconds. To get three milliseconds, one must write
8312 <literal>12.003</literal>, which the conversion treats as
8313 12 + 0.003 = 12.003 seconds.
8314 </para>
8316 <para>
8317 Here is a more
8318 complex example:
8319 <literal>to_timestamp('15:12:02.020.001230', 'HH24:MI:SS.MS.US')</literal>
8320 is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
8321 1230 microseconds = 2.021230 seconds.
8322 </para>
8323 </listitem>
8325 <listitem>
8326 <para>
8327 <function>to_char(..., 'ID')</function>'s day of the week numbering
8328 matches the <function>extract(isodow from ...)</function> function, but
8329 <function>to_char(..., 'D')</function>'s does not match
8330 <function>extract(dow from ...)</function>'s day numbering.
8331 </para>
8332 </listitem>
8334 <listitem>
8335 <para>
8336 <function>to_char(interval)</function> formats <literal>HH</literal> and
8337 <literal>HH12</literal> as shown on a 12-hour clock, for example zero hours
8338 and 36 hours both output as <literal>12</literal>, while <literal>HH24</literal>
8339 outputs the full hour value, which can exceed 23 in
8340 an <type>interval</type> value.
8341 </para>
8342 </listitem>
8344 </itemizedlist>
8345 </para>
8347 <para>
8348 <xref linkend="functions-formatting-numeric-table"/> shows the
8349 template patterns available for formatting numeric values.
8350 </para>
8352 <table id="functions-formatting-numeric-table">
8353 <title>Template Patterns for Numeric Formatting</title>
8354 <tgroup cols="2">
8355 <thead>
8356 <row>
8357 <entry>Pattern</entry>
8358 <entry>Description</entry>
8359 </row>
8360 </thead>
8361 <tbody>
8362 <row>
8363 <entry><literal>9</literal></entry>
8364 <entry>digit position (can be dropped if insignificant)</entry>
8365 </row>
8366 <row>
8367 <entry><literal>0</literal></entry>
8368 <entry>digit position (will not be dropped, even if insignificant)</entry>
8369 </row>
8370 <row>
8371 <entry><literal>.</literal> (period)</entry>
8372 <entry>decimal point</entry>
8373 </row>
8374 <row>
8375 <entry><literal>,</literal> (comma)</entry>
8376 <entry>group (thousands) separator</entry>
8377 </row>
8378 <row>
8379 <entry><literal>PR</literal></entry>
8380 <entry>negative value in angle brackets</entry>
8381 </row>
8382 <row>
8383 <entry><literal>S</literal></entry>
8384 <entry>sign anchored to number (uses locale)</entry>
8385 </row>
8386 <row>
8387 <entry><literal>L</literal></entry>
8388 <entry>currency symbol (uses locale)</entry>
8389 </row>
8390 <row>
8391 <entry><literal>D</literal></entry>
8392 <entry>decimal point (uses locale)</entry>
8393 </row>
8394 <row>
8395 <entry><literal>G</literal></entry>
8396 <entry>group separator (uses locale)</entry>
8397 </row>
8398 <row>
8399 <entry><literal>MI</literal></entry>
8400 <entry>minus sign in specified position (if number &lt; 0)</entry>
8401 </row>
8402 <row>
8403 <entry><literal>PL</literal></entry>
8404 <entry>plus sign in specified position (if number &gt; 0)</entry>
8405 </row>
8406 <row>
8407 <entry><literal>SG</literal></entry>
8408 <entry>plus/minus sign in specified position</entry>
8409 </row>
8410 <row>
8411 <entry><literal>RN</literal></entry>
8412 <entry>Roman numeral (input between 1 and 3999)</entry>
8413 </row>
8414 <row>
8415 <entry><literal>TH</literal> or <literal>th</literal></entry>
8416 <entry>ordinal number suffix</entry>
8417 </row>
8418 <row>
8419 <entry><literal>V</literal></entry>
8420 <entry>shift specified number of digits (see notes)</entry>
8421 </row>
8422 <row>
8423 <entry><literal>EEEE</literal></entry>
8424 <entry>exponent for scientific notation</entry>
8425 </row>
8426 </tbody>
8427 </tgroup>
8428 </table>
8430 <para>
8431 Usage notes for numeric formatting:
8433 <itemizedlist>
8434 <listitem>
8435 <para>
8436 <literal>0</literal> specifies a digit position that will always be printed,
8437 even if it contains a leading/trailing zero. <literal>9</literal> also
8438 specifies a digit position, but if it is a leading zero then it will
8439 be replaced by a space, while if it is a trailing zero and fill mode
8440 is specified then it will be deleted. (For <function>to_number()</function>,
8441 these two pattern characters are equivalent.)
8442 </para>
8443 </listitem>
8445 <listitem>
8446 <para>
8447 The pattern characters <literal>S</literal>, <literal>L</literal>, <literal>D</literal>,
8448 and <literal>G</literal> represent the sign, currency symbol, decimal point,
8449 and thousands separator characters defined by the current locale
8450 (see <xref linkend="guc-lc-monetary"/>
8451 and <xref linkend="guc-lc-numeric"/>). The pattern characters period
8452 and comma represent those exact characters, with the meanings of
8453 decimal point and thousands separator, regardless of locale.
8454 </para>
8455 </listitem>
8457 <listitem>
8458 <para>
8459 If no explicit provision is made for a sign
8460 in <function>to_char()</function>'s pattern, one column will be reserved for
8461 the sign, and it will be anchored to (appear just left of) the
8462 number. If <literal>S</literal> appears just left of some <literal>9</literal>'s,
8463 it will likewise be anchored to the number.
8464 </para>
8465 </listitem>
8467 <listitem>
8468 <para>
8469 A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
8470 <literal>MI</literal> is not anchored to
8471 the number; for example,
8472 <literal>to_char(-12, 'MI9999')</literal> produces <literal>'-&nbsp;&nbsp;12'</literal>
8473 but <literal>to_char(-12, 'S9999')</literal> produces <literal>'&nbsp;&nbsp;-12'</literal>.
8474 (The Oracle implementation does not allow the use of
8475 <literal>MI</literal> before <literal>9</literal>, but rather
8476 requires that <literal>9</literal> precede
8477 <literal>MI</literal>.)
8478 </para>
8479 </listitem>
8481 <listitem>
8482 <para>
8483 <literal>TH</literal> does not convert values less than zero
8484 and does not convert fractional numbers.
8485 </para>
8486 </listitem>
8488 <listitem>
8489 <para>
8490 <literal>PL</literal>, <literal>SG</literal>, and
8491 <literal>TH</literal> are <productname>PostgreSQL</productname>
8492 extensions.
8493 </para>
8494 </listitem>
8496 <listitem>
8497 <para>
8498 In <function>to_number</function>, if non-data template patterns such
8499 as <literal>L</literal> or <literal>TH</literal> are used, the
8500 corresponding number of input characters are skipped, whether or not
8501 they match the template pattern, unless they are data characters
8502 (that is, digits, sign, decimal point, or comma). For
8503 example, <literal>TH</literal> would skip two non-data characters.
8504 </para>
8505 </listitem>
8507 <listitem>
8508 <para>
8509 <literal>V</literal> with <function>to_char</function>
8510 multiplies the input values by
8511 <literal>10^<replaceable>n</replaceable></literal>, where
8512 <replaceable>n</replaceable> is the number of digits following
8513 <literal>V</literal>. <literal>V</literal> with
8514 <function>to_number</function> divides in a similar manner.
8515 <function>to_char</function> and <function>to_number</function>
8516 do not support the use of
8517 <literal>V</literal> combined with a decimal point
8518 (e.g., <literal>99.9V99</literal> is not allowed).
8519 </para>
8520 </listitem>
8522 <listitem>
8523 <para>
8524 <literal>EEEE</literal> (scientific notation) cannot be used in
8525 combination with any of the other formatting patterns or
8526 modifiers other than digit and decimal point patterns, and must be at the end of the format string
8527 (e.g., <literal>9.99EEEE</literal> is a valid pattern).
8528 </para>
8529 </listitem>
8530 </itemizedlist>
8531 </para>
8533 <para>
8534 Certain modifiers can be applied to any template pattern to alter its
8535 behavior. For example, <literal>FM99.99</literal>
8536 is the <literal>99.99</literal> pattern with the
8537 <literal>FM</literal> modifier.
8538 <xref linkend="functions-formatting-numericmod-table"/> shows the
8539 modifier patterns for numeric formatting.
8540 </para>
8542 <table id="functions-formatting-numericmod-table">
8543 <title>Template Pattern Modifiers for Numeric Formatting</title>
8544 <tgroup cols="3">
8545 <thead>
8546 <row>
8547 <entry>Modifier</entry>
8548 <entry>Description</entry>
8549 <entry>Example</entry>
8550 </row>
8551 </thead>
8552 <tbody>
8553 <row>
8554 <entry><literal>FM</literal> prefix</entry>
8555 <entry>fill mode (suppress trailing zeroes and padding blanks)</entry>
8556 <entry><literal>FM99.99</literal></entry>
8557 </row>
8558 <row>
8559 <entry><literal>TH</literal> suffix</entry>
8560 <entry>upper case ordinal number suffix</entry>
8561 <entry><literal>999TH</literal></entry>
8562 </row>
8563 <row>
8564 <entry><literal>th</literal> suffix</entry>
8565 <entry>lower case ordinal number suffix</entry>
8566 <entry><literal>999th</literal></entry>
8567 </row>
8568 </tbody>
8569 </tgroup>
8570 </table>
8572 <para>
8573 <xref linkend="functions-formatting-examples-table"/> shows some
8574 examples of the use of the <function>to_char</function> function.
8575 </para>
8577 <table id="functions-formatting-examples-table">
8578 <title><function>to_char</function> Examples</title>
8579 <tgroup cols="2">
8580 <thead>
8581 <row>
8582 <entry>Expression</entry>
8583 <entry>Result</entry>
8584 </row>
8585 </thead>
8586 <tbody>
8587 <row>
8588 <entry><literal>to_char(current_timestamp, 'Day,&nbsp;DD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8589 <entry><literal>'Tuesday&nbsp;&nbsp;,&nbsp;06&nbsp;&nbsp;05:39:18'</literal></entry>
8590 </row>
8591 <row>
8592 <entry><literal>to_char(current_timestamp, 'FMDay,&nbsp;FMDD&nbsp;&nbsp;HH12:MI:SS')</literal></entry>
8593 <entry><literal>'Tuesday,&nbsp;6&nbsp;&nbsp;05:39:18'</literal></entry>
8594 </row>
8595 <row>
8596 <entry><literal>to_char(-0.1, '99.99')</literal></entry>
8597 <entry><literal>'&nbsp;&nbsp;-.10'</literal></entry>
8598 </row>
8599 <row>
8600 <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
8601 <entry><literal>'-.1'</literal></entry>
8602 </row>
8603 <row>
8604 <entry><literal>to_char(-0.1, 'FM90.99')</literal></entry>
8605 <entry><literal>'-0.1'</literal></entry>
8606 </row>
8607 <row>
8608 <entry><literal>to_char(0.1, '0.9')</literal></entry>
8609 <entry><literal>'&nbsp;0.1'</literal></entry>
8610 </row>
8611 <row>
8612 <entry><literal>to_char(12, '9990999.9')</literal></entry>
8613 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;0012.0'</literal></entry>
8614 </row>
8615 <row>
8616 <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
8617 <entry><literal>'0012.'</literal></entry>
8618 </row>
8619 <row>
8620 <entry><literal>to_char(485, '999')</literal></entry>
8621 <entry><literal>'&nbsp;485'</literal></entry>
8622 </row>
8623 <row>
8624 <entry><literal>to_char(-485, '999')</literal></entry>
8625 <entry><literal>'-485'</literal></entry>
8626 </row>
8627 <row>
8628 <entry><literal>to_char(485, '9&nbsp;9&nbsp;9')</literal></entry>
8629 <entry><literal>'&nbsp;4&nbsp;8&nbsp;5'</literal></entry>
8630 </row>
8631 <row>
8632 <entry><literal>to_char(1485, '9,999')</literal></entry>
8633 <entry><literal>'&nbsp;1,485'</literal></entry>
8634 </row>
8635 <row>
8636 <entry><literal>to_char(1485, '9G999')</literal></entry>
8637 <entry><literal>'&nbsp;1&nbsp;485'</literal></entry>
8638 </row>
8639 <row>
8640 <entry><literal>to_char(148.5, '999.999')</literal></entry>
8641 <entry><literal>'&nbsp;148.500'</literal></entry>
8642 </row>
8643 <row>
8644 <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
8645 <entry><literal>'148.5'</literal></entry>
8646 </row>
8647 <row>
8648 <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
8649 <entry><literal>'148.500'</literal></entry>
8650 </row>
8651 <row>
8652 <entry><literal>to_char(148.5, '999D999')</literal></entry>
8653 <entry><literal>'&nbsp;148,500'</literal></entry>
8654 </row>
8655 <row>
8656 <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
8657 <entry><literal>'&nbsp;3&nbsp;148,500'</literal></entry>
8658 </row>
8659 <row>
8660 <entry><literal>to_char(-485, '999S')</literal></entry>
8661 <entry><literal>'485-'</literal></entry>
8662 </row>
8663 <row>
8664 <entry><literal>to_char(-485, '999MI')</literal></entry>
8665 <entry><literal>'485-'</literal></entry>
8666 </row>
8667 <row>
8668 <entry><literal>to_char(485, '999MI')</literal></entry>
8669 <entry><literal>'485&nbsp;'</literal></entry>
8670 </row>
8671 <row>
8672 <entry><literal>to_char(485, 'FM999MI')</literal></entry>
8673 <entry><literal>'485'</literal></entry>
8674 </row>
8675 <row>
8676 <entry><literal>to_char(485, 'PL999')</literal></entry>
8677 <entry><literal>'+485'</literal></entry>
8678 </row>
8679 <row>
8680 <entry><literal>to_char(485, 'SG999')</literal></entry>
8681 <entry><literal>'+485'</literal></entry>
8682 </row>
8683 <row>
8684 <entry><literal>to_char(-485, 'SG999')</literal></entry>
8685 <entry><literal>'-485'</literal></entry>
8686 </row>
8687 <row>
8688 <entry><literal>to_char(-485, '9SG99')</literal></entry>
8689 <entry><literal>'4-85'</literal></entry>
8690 </row>
8691 <row>
8692 <entry><literal>to_char(-485, '999PR')</literal></entry>
8693 <entry><literal>'&lt;485&gt;'</literal></entry>
8694 </row>
8695 <row>
8696 <entry><literal>to_char(485, 'L999')</literal></entry>
8697 <entry><literal>'DM&nbsp;485'</literal></entry>
8698 </row>
8699 <row>
8700 <entry><literal>to_char(485, 'RN')</literal></entry>
8701 <entry><literal>'&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;&nbsp;CDLXXXV'</literal></entry>
8702 </row>
8703 <row>
8704 <entry><literal>to_char(485, 'FMRN')</literal></entry>
8705 <entry><literal>'CDLXXXV'</literal></entry>
8706 </row>
8707 <row>
8708 <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
8709 <entry><literal>'V'</literal></entry>
8710 </row>
8711 <row>
8712 <entry><literal>to_char(482, '999th')</literal></entry>
8713 <entry><literal>'&nbsp;482nd'</literal></entry>
8714 </row>
8715 <row>
8716 <entry><literal>to_char(485, '"Good&nbsp;number:"999')</literal></entry>
8717 <entry><literal>'Good&nbsp;number:&nbsp;485'</literal></entry>
8718 </row>
8719 <row>
8720 <entry><literal>to_char(485.8, '"Pre:"999"&nbsp;Post:"&nbsp;.999')</literal></entry>
8721 <entry><literal>'Pre:&nbsp;485&nbsp;Post:&nbsp;.800'</literal></entry>
8722 </row>
8723 <row>
8724 <entry><literal>to_char(12, '99V999')</literal></entry>
8725 <entry><literal>'&nbsp;12000'</literal></entry>
8726 </row>
8727 <row>
8728 <entry><literal>to_char(12.4, '99V999')</literal></entry>
8729 <entry><literal>'&nbsp;12400'</literal></entry>
8730 </row>
8731 <row>
8732 <entry><literal>to_char(12.45, '99V9')</literal></entry>
8733 <entry><literal>'&nbsp;125'</literal></entry>
8734 </row>
8735 <row>
8736 <entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
8737 <entry><literal>' 4.86e-04'</literal></entry>
8738 </row>
8739 </tbody>
8740 </tgroup>
8741 </table>
8743 </sect1>
8746 <sect1 id="functions-datetime">
8747 <title>Date/Time Functions and Operators</title>
8749 <para>
8750 <xref linkend="functions-datetime-table"/> shows the available
8751 functions for date/time value processing, with details appearing in
8752 the following subsections. <xref
8753 linkend="operators-datetime-table"/> illustrates the behaviors of
8754 the basic arithmetic operators (<literal>+</literal>,
8755 <literal>*</literal>, etc.). For formatting functions, refer to
8756 <xref linkend="functions-formatting"/>. You should be familiar with
8757 the background information on date/time data types from <xref
8758 linkend="datatype-datetime"/>.
8759 </para>
8761 <para>
8762 In addition, the usual comparison operators shown in
8763 <xref linkend="functions-comparison-op-table"/> are available for the
8764 date/time types. Dates and timestamps (with or without time zone) are
8765 all comparable, while times (with or without time zone) and intervals
8766 can only be compared to other values of the same data type. When
8767 comparing a timestamp without time zone to a timestamp with time zone,
8768 the former value is assumed to be given in the time zone specified by
8769 the <xref linkend="guc-timezone"/> configuration parameter, and is
8770 rotated to UTC for comparison to the latter value (which is already
8771 in UTC internally). Similarly, a date value is assumed to represent
8772 midnight in the <varname>TimeZone</varname> zone when comparing it
8773 to a timestamp.
8774 </para>
8776 <para>
8777 All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
8778 inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
8779 with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
8780 For brevity, these variants are not shown separately. Also, the
8781 <literal>+</literal> and <literal>*</literal> operators come in commutative pairs (for
8782 example both <type>date</type> <literal>+</literal> <type>integer</type>
8783 and <type>integer</type> <literal>+</literal> <type>date</type>); we show
8784 only one of each such pair.
8785 </para>
8787 <table id="operators-datetime-table">
8788 <title>Date/Time Operators</title>
8790 <tgroup cols="1">
8791 <thead>
8792 <row>
8793 <entry role="func_table_entry"><para role="func_signature">
8794 Operator
8795 </para>
8796 <para>
8797 Description
8798 </para>
8799 <para>
8800 Example(s)
8801 </para></entry>
8802 </row>
8803 </thead>
8805 <tbody>
8806 <row>
8807 <entry role="func_table_entry"><para role="func_signature">
8808 <type>date</type> <literal>+</literal> <type>integer</type>
8809 <returnvalue>date</returnvalue>
8810 </para>
8811 <para>
8812 Add a number of days to a date
8813 </para>
8814 <para>
8815 <literal>date '2001-09-28' + 7</literal>
8816 <returnvalue>2001-10-05</returnvalue>
8817 </para></entry>
8818 </row>
8820 <row>
8821 <entry role="func_table_entry"><para role="func_signature">
8822 <type>date</type> <literal>+</literal> <type>interval</type>
8823 <returnvalue>timestamp</returnvalue>
8824 </para>
8825 <para>
8826 Add an interval to a date
8827 </para>
8828 <para>
8829 <literal>date '2001-09-28' + interval '1 hour'</literal>
8830 <returnvalue>2001-09-28 01:00:00</returnvalue>
8831 </para></entry>
8832 </row>
8834 <row>
8835 <entry role="func_table_entry"><para role="func_signature">
8836 <type>date</type> <literal>+</literal> <type>time</type>
8837 <returnvalue>timestamp</returnvalue>
8838 </para>
8839 <para>
8840 Add a time-of-day to a date
8841 </para>
8842 <para>
8843 <literal>date '2001-09-28' + time '03:00'</literal>
8844 <returnvalue>2001-09-28 03:00:00</returnvalue>
8845 </para></entry>
8846 </row>
8848 <row>
8849 <entry role="func_table_entry"><para role="func_signature">
8850 <type>interval</type> <literal>+</literal> <type>interval</type>
8851 <returnvalue>interval</returnvalue>
8852 </para>
8853 <para>
8854 Add intervals
8855 </para>
8856 <para>
8857 <literal>interval '1 day' + interval '1 hour'</literal>
8858 <returnvalue>1 day 01:00:00</returnvalue>
8859 </para></entry>
8860 </row>
8862 <row>
8863 <entry role="func_table_entry"><para role="func_signature">
8864 <type>timestamp</type> <literal>+</literal> <type>interval</type>
8865 <returnvalue>timestamp</returnvalue>
8866 </para>
8867 <para>
8868 Add an interval to a timestamp
8869 </para>
8870 <para>
8871 <literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal>
8872 <returnvalue>2001-09-29 00:00:00</returnvalue>
8873 </para></entry>
8874 </row>
8876 <row>
8877 <entry role="func_table_entry"><para role="func_signature">
8878 <type>time</type> <literal>+</literal> <type>interval</type>
8879 <returnvalue>time</returnvalue>
8880 </para>
8881 <para>
8882 Add an interval to a time
8883 </para>
8884 <para>
8885 <literal>time '01:00' + interval '3 hours'</literal>
8886 <returnvalue>04:00:00</returnvalue>
8887 </para></entry>
8888 </row>
8890 <row>
8891 <entry role="func_table_entry"><para role="func_signature">
8892 <literal>-</literal> <type>interval</type>
8893 <returnvalue>interval</returnvalue>
8894 </para>
8895 <para>
8896 Negate an interval
8897 </para>
8898 <para>
8899 <literal>- interval '23 hours'</literal>
8900 <returnvalue>-23:00:00</returnvalue>
8901 </para></entry>
8902 </row>
8904 <row>
8905 <entry role="func_table_entry"><para role="func_signature">
8906 <type>date</type> <literal>-</literal> <type>date</type>
8907 <returnvalue>integer</returnvalue>
8908 </para>
8909 <para>
8910 Subtract dates, producing the number of days elapsed
8911 </para>
8912 <para>
8913 <literal>date '2001-10-01' - date '2001-09-28'</literal>
8914 <returnvalue>3</returnvalue>
8915 </para></entry>
8916 </row>
8918 <row>
8919 <entry role="func_table_entry"><para role="func_signature">
8920 <type>date</type> <literal>-</literal> <type>integer</type>
8921 <returnvalue>date</returnvalue>
8922 </para>
8923 <para>
8924 Subtract a number of days from a date
8925 </para>
8926 <para>
8927 <literal>date '2001-10-01' - 7</literal>
8928 <returnvalue>2001-09-24</returnvalue>
8929 </para></entry>
8930 </row>
8932 <row>
8933 <entry role="func_table_entry"><para role="func_signature">
8934 <type>date</type> <literal>-</literal> <type>interval</type>
8935 <returnvalue>timestamp</returnvalue>
8936 </para>
8937 <para>
8938 Subtract an interval from a date
8939 </para>
8940 <para>
8941 <literal>date '2001-09-28' - interval '1 hour'</literal>
8942 <returnvalue>2001-09-27 23:00:00</returnvalue>
8943 </para></entry>
8944 </row>
8946 <row>
8947 <entry role="func_table_entry"><para role="func_signature">
8948 <type>time</type> <literal>-</literal> <type>time</type>
8949 <returnvalue>interval</returnvalue>
8950 </para>
8951 <para>
8952 Subtract times
8953 </para>
8954 <para>
8955 <literal>time '05:00' - time '03:00'</literal>
8956 <returnvalue>02:00:00</returnvalue>
8957 </para></entry>
8958 </row>
8960 <row>
8961 <entry role="func_table_entry"><para role="func_signature">
8962 <type>time</type> <literal>-</literal> <type>interval</type>
8963 <returnvalue>time</returnvalue>
8964 </para>
8965 <para>
8966 Subtract an interval from a time
8967 </para>
8968 <para>
8969 <literal>time '05:00' - interval '2 hours'</literal>
8970 <returnvalue>03:00:00</returnvalue>
8971 </para></entry>
8972 </row>
8974 <row>
8975 <entry role="func_table_entry"><para role="func_signature">
8976 <type>timestamp</type> <literal>-</literal> <type>interval</type>
8977 <returnvalue>timestamp</returnvalue>
8978 </para>
8979 <para>
8980 Subtract an interval from a timestamp
8981 </para>
8982 <para>
8983 <literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal>
8984 <returnvalue>2001-09-28 00:00:00</returnvalue>
8985 </para></entry>
8986 </row>
8988 <row>
8989 <entry role="func_table_entry"><para role="func_signature">
8990 <type>interval</type> <literal>-</literal> <type>interval</type>
8991 <returnvalue>interval</returnvalue>
8992 </para>
8993 <para>
8994 Subtract intervals
8995 </para>
8996 <para>
8997 <literal>interval '1 day' - interval '1 hour'</literal>
8998 <returnvalue>1 day -01:00:00</returnvalue>
8999 </para></entry>
9000 </row>
9002 <row>
9003 <entry role="func_table_entry"><para role="func_signature">
9004 <type>timestamp</type> <literal>-</literal> <type>timestamp</type>
9005 <returnvalue>interval</returnvalue>
9006 </para>
9007 <para>
9008 Subtract timestamps (converting 24-hour intervals into days,
9009 similarly to <function>justify_hours()</function>)
9010 </para>
9011 <para>
9012 <literal>timestamp '2001-09-29 03:00' - timestamp '2001-07-27 12:00'</literal>
9013 <returnvalue>63 days 15:00:00</returnvalue>
9014 </para></entry>
9015 </row>
9017 <row>
9018 <entry role="func_table_entry"><para role="func_signature">
9019 <type>interval</type> <literal>*</literal> <type>double precision</type>
9020 <returnvalue>interval</returnvalue>
9021 </para>
9022 <para>
9023 Multiply an interval by a scalar
9024 </para>
9025 <para>
9026 <literal>interval '1 second' * 900</literal>
9027 <returnvalue>00:15:00</returnvalue>
9028 </para>
9029 <para>
9030 <literal>interval '1 day' * 21</literal>
9031 <returnvalue>21 days</returnvalue>
9032 </para>
9033 <para>
9034 <literal>interval '1 hour' * 3.5</literal>
9035 <returnvalue>03:30:00</returnvalue>
9036 </para></entry>
9037 </row>
9039 <row>
9040 <entry role="func_table_entry"><para role="func_signature">
9041 <type>interval</type> <literal>/</literal> <type>double precision</type>
9042 <returnvalue>interval</returnvalue>
9043 </para>
9044 <para>
9045 Divide an interval by a scalar
9046 </para>
9047 <para>
9048 <literal>interval '1 hour' / 1.5</literal>
9049 <returnvalue>00:40:00</returnvalue>
9050 </para></entry>
9051 </row>
9052 </tbody>
9053 </tgroup>
9054 </table>
9056 <table id="functions-datetime-table">
9057 <title>Date/Time Functions</title>
9058 <tgroup cols="1">
9059 <thead>
9060 <row>
9061 <entry role="func_table_entry"><para role="func_signature">
9062 Function
9063 </para>
9064 <para>
9065 Description
9066 </para>
9067 <para>
9068 Example(s)
9069 </para></entry>
9070 </row>
9071 </thead>
9073 <tbody>
9074 <row>
9075 <entry role="func_table_entry"><para role="func_signature">
9076 <indexterm>
9077 <primary>age</primary>
9078 </indexterm>
9079 <function>age</function> ( <type>timestamp</type>, <type>timestamp</type> )
9080 <returnvalue>interval</returnvalue>
9081 </para>
9082 <para>
9083 Subtract arguments, producing a <quote>symbolic</quote> result that
9084 uses years and months, rather than just days
9085 </para>
9086 <para>
9087 <literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal>
9088 <returnvalue>43 years 9 mons 27 days</returnvalue>
9089 </para></entry>
9090 </row>
9092 <row>
9093 <entry role="func_table_entry"><para role="func_signature">
9094 <function>age</function> ( <type>timestamp</type> )
9095 <returnvalue>interval</returnvalue>
9096 </para>
9097 <para>
9098 Subtract argument from <function>current_date</function> (at midnight)
9099 </para>
9100 <para>
9101 <literal>age(timestamp '1957-06-13')</literal>
9102 <returnvalue>62 years 6 mons 10 days</returnvalue>
9103 </para></entry>
9104 </row>
9106 <row>
9107 <entry role="func_table_entry"><para role="func_signature">
9108 <indexterm>
9109 <primary>clock_timestamp</primary>
9110 </indexterm>
9111 <function>clock_timestamp</function> ( )
9112 <returnvalue>timestamp with time zone</returnvalue>
9113 </para>
9114 <para>
9115 Current date and time (changes during statement execution);
9116 see <xref linkend="functions-datetime-current"/>
9117 </para>
9118 <para>
9119 <literal>clock_timestamp()</literal>
9120 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9121 </para></entry>
9122 </row>
9124 <row>
9125 <entry role="func_table_entry"><para role="func_signature">
9126 <indexterm>
9127 <primary>current_date</primary>
9128 </indexterm>
9129 <function>current_date</function>
9130 <returnvalue>date</returnvalue>
9131 </para>
9132 <para>
9133 Current date; see <xref linkend="functions-datetime-current"/>
9134 </para>
9135 <para>
9136 <literal>current_date</literal>
9137 <returnvalue>2019-12-23</returnvalue>
9138 </para></entry>
9139 </row>
9141 <row>
9142 <entry role="func_table_entry"><para role="func_signature">
9143 <indexterm>
9144 <primary>current_time</primary>
9145 </indexterm>
9146 <function>current_time</function>
9147 <returnvalue>time with time zone</returnvalue>
9148 </para>
9149 <para>
9150 Current time of day; see <xref linkend="functions-datetime-current"/>
9151 </para>
9152 <para>
9153 <literal>current_time</literal>
9154 <returnvalue>14:39:53.662522-05</returnvalue>
9155 </para></entry>
9156 </row>
9158 <row>
9159 <entry role="func_table_entry"><para role="func_signature">
9160 <function>current_time</function> ( <type>integer</type> )
9161 <returnvalue>time with time zone</returnvalue>
9162 </para>
9163 <para>
9164 Current time of day, with limited precision;
9165 see <xref linkend="functions-datetime-current"/>
9166 </para>
9167 <para>
9168 <literal>current_time(2)</literal>
9169 <returnvalue>14:39:53.66-05</returnvalue>
9170 </para></entry>
9171 </row>
9173 <row>
9174 <entry role="func_table_entry"><para role="func_signature">
9175 <indexterm>
9176 <primary>current_timestamp</primary>
9177 </indexterm>
9178 <function>current_timestamp</function>
9179 <returnvalue>timestamp with time zone</returnvalue>
9180 </para>
9181 <para>
9182 Current date and time (start of current transaction);
9183 see <xref linkend="functions-datetime-current"/>
9184 </para>
9185 <para>
9186 <literal>current_timestamp</literal>
9187 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9188 </para></entry>
9189 </row>
9191 <row>
9192 <entry role="func_table_entry"><para role="func_signature">
9193 <function>current_timestamp</function> ( <type>integer</type> )
9194 <returnvalue>timestamp with time zone</returnvalue>
9195 </para>
9196 <para>
9197 Current date and time (start of current transaction), with limited precision;
9198 see <xref linkend="functions-datetime-current"/>
9199 </para>
9200 <para>
9201 <literal>current_timestamp(0)</literal>
9202 <returnvalue>2019-12-23 14:39:53-05</returnvalue>
9203 </para></entry>
9204 </row>
9206 <row>
9207 <entry role="func_table_entry"><para role="func_signature">
9208 <function>date_bin</function> ( <type>interval</type>, <type>timestamp</type>, <type>timestamp</type> )
9209 <returnvalue>timestamp</returnvalue>
9210 </para>
9211 <para>
9212 Bin input into specified interval aligned with specified origin; see <xref linkend="functions-datetime-bin"/>
9213 </para>
9214 <para>
9215 <literal>date_bin('15 minutes', timestamp '2001-02-16 20:38:40', timestamp '2001-02-16 20:05:00')</literal>
9216 <returnvalue>2001-02-16 20:35:00</returnvalue>
9217 </para></entry>
9218 </row>
9220 <row>
9221 <entry role="func_table_entry"><para role="func_signature">
9222 <indexterm>
9223 <primary>date_part</primary>
9224 </indexterm>
9225 <function>date_part</function> ( <type>text</type>, <type>timestamp</type> )
9226 <returnvalue>double precision</returnvalue>
9227 </para>
9228 <para>
9229 Get timestamp subfield (equivalent to <function>extract</function>);
9230 see <xref linkend="functions-datetime-extract"/>
9231 </para>
9232 <para>
9233 <literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal>
9234 <returnvalue>20</returnvalue>
9235 </para></entry>
9236 </row>
9238 <row>
9239 <entry role="func_table_entry"><para role="func_signature">
9240 <function>date_part</function> ( <type>text</type>, <type>interval</type> )
9241 <returnvalue>double precision</returnvalue>
9242 </para>
9243 <para>
9244 Get interval subfield (equivalent to <function>extract</function>);
9245 see <xref linkend="functions-datetime-extract"/>
9246 </para>
9247 <para>
9248 <literal>date_part('month', interval '2 years 3 months')</literal>
9249 <returnvalue>3</returnvalue>
9250 </para></entry>
9251 </row>
9253 <row>
9254 <entry role="func_table_entry"><para role="func_signature">
9255 <indexterm>
9256 <primary>date_trunc</primary>
9257 </indexterm>
9258 <function>date_trunc</function> ( <type>text</type>, <type>timestamp</type> )
9259 <returnvalue>timestamp</returnvalue>
9260 </para>
9261 <para>
9262 Truncate to specified precision; see <xref linkend="functions-datetime-trunc"/>
9263 </para>
9264 <para>
9265 <literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal>
9266 <returnvalue>2001-02-16 20:00:00</returnvalue>
9267 </para></entry>
9268 </row>
9270 <row>
9271 <entry role="func_table_entry"><para role="func_signature">
9272 <function>date_trunc</function> ( <type>text</type>, <type>timestamp with time zone</type>, <type>text</type> )
9273 <returnvalue>timestamp with time zone</returnvalue>
9274 </para>
9275 <para>
9276 Truncate to specified precision in the specified time zone; see
9277 <xref linkend="functions-datetime-trunc"/>
9278 </para>
9279 <para>
9280 <literal>date_trunc('day', timestamptz '2001-02-16 20:38:40+00', 'Australia/Sydney')</literal>
9281 <returnvalue>2001-02-16 13:00:00+00</returnvalue>
9282 </para></entry>
9283 </row>
9285 <row>
9286 <entry role="func_table_entry"><para role="func_signature">
9287 <function>date_trunc</function> ( <type>text</type>, <type>interval</type> )
9288 <returnvalue>interval</returnvalue>
9289 </para>
9290 <para>
9291 Truncate to specified precision; see
9292 <xref linkend="functions-datetime-trunc"/>
9293 </para>
9294 <para>
9295 <literal>date_trunc('hour', interval '2 days 3 hours 40 minutes')</literal>
9296 <returnvalue>2 days 03:00:00</returnvalue>
9297 </para></entry>
9298 </row>
9300 <row>
9301 <entry role="func_table_entry"><para role="func_signature">
9302 <indexterm>
9303 <primary>extract</primary>
9304 </indexterm>
9305 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>timestamp</type> )
9306 <returnvalue>numeric</returnvalue>
9307 </para>
9308 <para>
9309 Get timestamp subfield; see <xref linkend="functions-datetime-extract"/>
9310 </para>
9311 <para>
9312 <literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal>
9313 <returnvalue>20</returnvalue>
9314 </para></entry>
9315 </row>
9317 <row>
9318 <entry role="func_table_entry"><para role="func_signature">
9319 <function>extract</function> ( <parameter>field</parameter> <literal>from</literal> <type>interval</type> )
9320 <returnvalue>numeric</returnvalue>
9321 </para>
9322 <para>
9323 Get interval subfield; see <xref linkend="functions-datetime-extract"/>
9324 </para>
9325 <para>
9326 <literal>extract(month from interval '2 years 3 months')</literal>
9327 <returnvalue>3</returnvalue>
9328 </para></entry>
9329 </row>
9331 <row>
9332 <entry role="func_table_entry"><para role="func_signature">
9333 <indexterm>
9334 <primary>isfinite</primary>
9335 </indexterm>
9336 <function>isfinite</function> ( <type>date</type> )
9337 <returnvalue>boolean</returnvalue>
9338 </para>
9339 <para>
9340 Test for finite date (not +/-infinity)
9341 </para>
9342 <para>
9343 <literal>isfinite(date '2001-02-16')</literal>
9344 <returnvalue>true</returnvalue>
9345 </para></entry>
9346 </row>
9348 <row>
9349 <entry role="func_table_entry"><para role="func_signature">
9350 <function>isfinite</function> ( <type>timestamp</type> )
9351 <returnvalue>boolean</returnvalue>
9352 </para>
9353 <para>
9354 Test for finite timestamp (not +/-infinity)
9355 </para>
9356 <para>
9357 <literal>isfinite(timestamp 'infinity')</literal>
9358 <returnvalue>false</returnvalue>
9359 </para></entry>
9360 </row>
9362 <row>
9363 <entry role="func_table_entry"><para role="func_signature">
9364 <function>isfinite</function> ( <type>interval</type> )
9365 <returnvalue>boolean</returnvalue>
9366 </para>
9367 <para>
9368 Test for finite interval (currently always true)
9369 </para>
9370 <para>
9371 <literal>isfinite(interval '4 hours')</literal>
9372 <returnvalue>true</returnvalue>
9373 </para></entry>
9374 </row>
9376 <row>
9377 <entry role="func_table_entry"><para role="func_signature">
9378 <indexterm>
9379 <primary>justify_days</primary>
9380 </indexterm>
9381 <function>justify_days</function> ( <type>interval</type> )
9382 <returnvalue>interval</returnvalue>
9383 </para>
9384 <para>
9385 Adjust interval so 30-day time periods are represented as months
9386 </para>
9387 <para>
9388 <literal>justify_days(interval '35 days')</literal>
9389 <returnvalue>1 mon 5 days</returnvalue>
9390 </para></entry>
9391 </row>
9393 <row>
9394 <entry role="func_table_entry"><para role="func_signature">
9395 <indexterm>
9396 <primary>justify_hours</primary>
9397 </indexterm>
9398 <function>justify_hours</function> ( <type>interval</type> )
9399 <returnvalue>interval</returnvalue>
9400 </para>
9401 <para>
9402 Adjust interval so 24-hour time periods are represented as days
9403 </para>
9404 <para>
9405 <literal>justify_hours(interval '27 hours')</literal>
9406 <returnvalue>1 day 03:00:00</returnvalue>
9407 </para></entry>
9408 </row>
9410 <row>
9411 <entry role="func_table_entry"><para role="func_signature">
9412 <indexterm>
9413 <primary>justify_interval</primary>
9414 </indexterm>
9415 <function>justify_interval</function> ( <type>interval</type> )
9416 <returnvalue>interval</returnvalue>
9417 </para>
9418 <para>
9419 Adjust interval using <function>justify_days</function>
9420 and <function>justify_hours</function>, with additional sign
9421 adjustments
9422 </para>
9423 <para>
9424 <literal>justify_interval(interval '1 mon -1 hour')</literal>
9425 <returnvalue>29 days 23:00:00</returnvalue>
9426 </para></entry>
9427 </row>
9429 <row>
9430 <entry role="func_table_entry"><para role="func_signature">
9431 <indexterm>
9432 <primary>localtime</primary>
9433 </indexterm>
9434 <function>localtime</function>
9435 <returnvalue>time</returnvalue>
9436 </para>
9437 <para>
9438 Current time of day;
9439 see <xref linkend="functions-datetime-current"/>
9440 </para>
9441 <para>
9442 <literal>localtime</literal>
9443 <returnvalue>14:39:53.662522</returnvalue>
9444 </para></entry>
9445 </row>
9447 <row>
9448 <entry role="func_table_entry"><para role="func_signature">
9449 <function>localtime</function> ( <type>integer</type> )
9450 <returnvalue>time</returnvalue>
9451 </para>
9452 <para>
9453 Current time of day, with limited precision;
9454 see <xref linkend="functions-datetime-current"/>
9455 </para>
9456 <para>
9457 <literal>localtime(0)</literal>
9458 <returnvalue>14:39:53</returnvalue>
9459 </para></entry>
9460 </row>
9462 <row>
9463 <entry role="func_table_entry"><para role="func_signature">
9464 <indexterm>
9465 <primary>localtimestamp</primary>
9466 </indexterm>
9467 <function>localtimestamp</function>
9468 <returnvalue>timestamp</returnvalue>
9469 </para>
9470 <para>
9471 Current date and time (start of current transaction);
9472 see <xref linkend="functions-datetime-current"/>
9473 </para>
9474 <para>
9475 <literal>localtimestamp</literal>
9476 <returnvalue>2019-12-23 14:39:53.662522</returnvalue>
9477 </para></entry>
9478 </row>
9480 <row>
9481 <entry role="func_table_entry"><para role="func_signature">
9482 <function>localtimestamp</function> ( <type>integer</type> )
9483 <returnvalue>timestamp</returnvalue>
9484 </para>
9485 <para>
9486 Current date and time (start of current
9487 transaction), with limited precision;
9488 see <xref linkend="functions-datetime-current"/>
9489 </para>
9490 <para>
9491 <literal>localtimestamp(2)</literal>
9492 <returnvalue>2019-12-23 14:39:53.66</returnvalue>
9493 </para></entry>
9494 </row>
9496 <row>
9497 <entry role="func_table_entry"><para role="func_signature">
9498 <indexterm>
9499 <primary>make_date</primary>
9500 </indexterm>
9501 <function>make_date</function> ( <parameter>year</parameter> <type>int</type>,
9502 <parameter>month</parameter> <type>int</type>,
9503 <parameter>day</parameter> <type>int</type> )
9504 <returnvalue>date</returnvalue>
9505 </para>
9506 <para>
9507 Create date from year, month and day fields
9508 (negative years signify BC)
9509 </para>
9510 <para>
9511 <literal>make_date(2013, 7, 15)</literal>
9512 <returnvalue>2013-07-15</returnvalue>
9513 </para></entry>
9514 </row>
9516 <row>
9517 <entry role="func_table_entry"><para role="func_signature"><indexterm>
9518 <primary>make_interval</primary>
9519 </indexterm>
9520 <function>make_interval</function> ( <optional> <parameter>years</parameter> <type>int</type>
9521 <optional>, <parameter>months</parameter> <type>int</type>
9522 <optional>, <parameter>weeks</parameter> <type>int</type>
9523 <optional>, <parameter>days</parameter> <type>int</type>
9524 <optional>, <parameter>hours</parameter> <type>int</type>
9525 <optional>, <parameter>mins</parameter> <type>int</type>
9526 <optional>, <parameter>secs</parameter> <type>double precision</type>
9527 </optional></optional></optional></optional></optional></optional></optional> )
9528 <returnvalue>interval</returnvalue>
9529 </para>
9530 <para>
9531 Create interval from years, months, weeks, days, hours, minutes and
9532 seconds fields, each of which can default to zero
9533 </para>
9534 <para>
9535 <literal>make_interval(days =&gt; 10)</literal>
9536 <returnvalue>10 days</returnvalue>
9537 </para></entry>
9538 </row>
9540 <row>
9541 <entry role="func_table_entry"><para role="func_signature">
9542 <indexterm>
9543 <primary>make_time</primary>
9544 </indexterm>
9545 <function>make_time</function> ( <parameter>hour</parameter> <type>int</type>,
9546 <parameter>min</parameter> <type>int</type>,
9547 <parameter>sec</parameter> <type>double precision</type> )
9548 <returnvalue>time</returnvalue>
9549 </para>
9550 <para>
9551 Create time from hour, minute and seconds fields
9552 </para>
9553 <para>
9554 <literal>make_time(8, 15, 23.5)</literal>
9555 <returnvalue>08:15:23.5</returnvalue>
9556 </para></entry>
9557 </row>
9559 <row>
9560 <entry role="func_table_entry"><para role="func_signature">
9561 <indexterm>
9562 <primary>make_timestamp</primary>
9563 </indexterm>
9564 <function>make_timestamp</function> ( <parameter>year</parameter> <type>int</type>,
9565 <parameter>month</parameter> <type>int</type>,
9566 <parameter>day</parameter> <type>int</type>,
9567 <parameter>hour</parameter> <type>int</type>,
9568 <parameter>min</parameter> <type>int</type>,
9569 <parameter>sec</parameter> <type>double precision</type> )
9570 <returnvalue>timestamp</returnvalue>
9571 </para>
9572 <para>
9573 Create timestamp from year, month, day, hour, minute and seconds fields
9574 (negative years signify BC)
9575 </para>
9576 <para>
9577 <literal>make_timestamp(2013, 7, 15, 8, 15, 23.5)</literal>
9578 <returnvalue>2013-07-15 08:15:23.5</returnvalue>
9579 </para></entry>
9580 </row>
9582 <row>
9583 <entry role="func_table_entry"><para role="func_signature">
9584 <indexterm>
9585 <primary>make_timestamptz</primary>
9586 </indexterm>
9587 <function>make_timestamptz</function> ( <parameter>year</parameter> <type>int</type>,
9588 <parameter>month</parameter> <type>int</type>,
9589 <parameter>day</parameter> <type>int</type>,
9590 <parameter>hour</parameter> <type>int</type>,
9591 <parameter>min</parameter> <type>int</type>,
9592 <parameter>sec</parameter> <type>double precision</type>
9593 <optional>, <parameter>timezone</parameter> <type>text</type> </optional> )
9594 <returnvalue>timestamp with time zone</returnvalue>
9595 </para>
9596 <para>
9597 Create timestamp with time zone from year, month, day, hour, minute
9598 and seconds fields (negative years signify BC).
9599 If <parameter>timezone</parameter> is not
9600 specified, the current time zone is used; the examples assume the
9601 session time zone is <literal>Europe/London</literal>
9602 </para>
9603 <para>
9604 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5)</literal>
9605 <returnvalue>2013-07-15 08:15:23.5+01</returnvalue>
9606 </para>
9607 <para>
9608 <literal>make_timestamptz(2013, 7, 15, 8, 15, 23.5, 'America/New_York')</literal>
9609 <returnvalue>2013-07-15 13:15:23.5+01</returnvalue>
9610 </para></entry>
9611 </row>
9613 <row>
9614 <entry role="func_table_entry"><para role="func_signature">
9615 <indexterm>
9616 <primary>now</primary>
9617 </indexterm>
9618 <function>now</function> ( )
9619 <returnvalue>timestamp with time zone</returnvalue>
9620 </para>
9621 <para>
9622 Current date and time (start of current transaction);
9623 see <xref linkend="functions-datetime-current"/>
9624 </para>
9625 <para>
9626 <literal>now()</literal>
9627 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9628 </para></entry>
9629 </row>
9631 <row>
9632 <entry role="func_table_entry"><para role="func_signature">
9633 <indexterm>
9634 <primary>statement_timestamp</primary>
9635 </indexterm>
9636 <function>statement_timestamp</function> ( )
9637 <returnvalue>timestamp with time zone</returnvalue>
9638 </para>
9639 <para>
9640 Current date and time (start of current statement);
9641 see <xref linkend="functions-datetime-current"/>
9642 </para>
9643 <para>
9644 <literal>statement_timestamp()</literal>
9645 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9646 </para></entry>
9647 </row>
9649 <row>
9650 <entry role="func_table_entry"><para role="func_signature">
9651 <indexterm>
9652 <primary>timeofday</primary>
9653 </indexterm>
9654 <function>timeofday</function> ( )
9655 <returnvalue>text</returnvalue>
9656 </para>
9657 <para>
9658 Current date and time
9659 (like <function>clock_timestamp</function>, but as a <type>text</type> string);
9660 see <xref linkend="functions-datetime-current"/>
9661 </para>
9662 <para>
9663 <literal>timeofday()</literal>
9664 <returnvalue>Mon Dec 23 14:39:53.662522 2019 EST</returnvalue>
9665 </para></entry>
9666 </row>
9668 <row>
9669 <entry role="func_table_entry"><para role="func_signature">
9670 <indexterm>
9671 <primary>transaction_timestamp</primary>
9672 </indexterm>
9673 <function>transaction_timestamp</function> ( )
9674 <returnvalue>timestamp with time zone</returnvalue>
9675 </para>
9676 <para>
9677 Current date and time (start of current transaction);
9678 see <xref linkend="functions-datetime-current"/>
9679 </para>
9680 <para>
9681 <literal>transaction_timestamp()</literal>
9682 <returnvalue>2019-12-23 14:39:53.662522-05</returnvalue>
9683 </para></entry>
9684 </row>
9686 <row>
9687 <entry role="func_table_entry"><para role="func_signature">
9688 <indexterm>
9689 <primary>to_timestamp</primary>
9690 </indexterm>
9691 <function>to_timestamp</function> ( <type>double precision</type> )
9692 <returnvalue>timestamp with time zone</returnvalue>
9693 </para>
9694 <para>
9695 Convert Unix epoch (seconds since 1970-01-01 00:00:00+00) to
9696 timestamp with time zone
9697 </para>
9698 <para>
9699 <literal>to_timestamp(1284352323)</literal>
9700 <returnvalue>2010-09-13 04:32:03+00</returnvalue>
9701 </para></entry>
9702 </row>
9703 </tbody>
9704 </tgroup>
9705 </table>
9707 <para>
9708 <indexterm>
9709 <primary>OVERLAPS</primary>
9710 </indexterm>
9711 In addition to these functions, the SQL <literal>OVERLAPS</literal> operator is
9712 supported:
9713 <synopsis>
9714 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
9715 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
9716 </synopsis>
9717 This expression yields true when two time periods (defined by their
9718 endpoints) overlap, false when they do not overlap. The endpoints
9719 can be specified as pairs of dates, times, or time stamps; or as
9720 a date, time, or time stamp followed by an interval. When a pair
9721 of values is provided, either the start or the end can be written
9722 first; <literal>OVERLAPS</literal> automatically takes the earlier value
9723 of the pair as the start. Each time period is considered to
9724 represent the half-open interval <replaceable>start</replaceable> <literal>&lt;=</literal>
9725 <replaceable>time</replaceable> <literal>&lt;</literal> <replaceable>end</replaceable>, unless
9726 <replaceable>start</replaceable> and <replaceable>end</replaceable> are equal in which case it
9727 represents that single time instant. This means for instance that two
9728 time periods with only an endpoint in common do not overlap.
9729 </para>
9731 <screen>
9732 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
9733 (DATE '2001-10-30', DATE '2002-10-30');
9734 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
9735 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
9736 (DATE '2001-10-30', DATE '2002-10-30');
9737 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
9738 SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
9739 (DATE '2001-10-30', DATE '2001-10-31');
9740 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
9741 SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
9742 (DATE '2001-10-30', DATE '2001-10-31');
9743 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
9744 </screen>
9746 <para>
9747 When adding an <type>interval</type> value to (or subtracting an
9748 <type>interval</type> value from) a <type>timestamp with time zone</type>
9749 value, the days component advances or decrements the date of the
9750 <type>timestamp with time zone</type> by the indicated number of days,
9751 keeping the time of day the same.
9752 Across daylight saving time changes (when the session time zone is set to a
9753 time zone that recognizes DST), this means <literal>interval '1 day'</literal>
9754 does not necessarily equal <literal>interval '24 hours'</literal>.
9755 For example, with the session time zone set
9756 to <literal>America/Denver</literal>:
9757 <screen>
9758 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '1 day';
9759 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 12:00:00-06</computeroutput>
9760 SELECT timestamp with time zone '2005-04-02 12:00:00-07' + interval '24 hours';
9761 <lineannotation>Result: </lineannotation><computeroutput>2005-04-03 13:00:00-06</computeroutput>
9762 </screen>
9763 This happens because an hour was skipped due to a change in daylight saving
9764 time at <literal>2005-04-03 02:00:00</literal> in time zone
9765 <literal>America/Denver</literal>.
9766 </para>
9768 <para>
9769 Note there can be ambiguity in the <literal>months</literal> field returned by
9770 <function>age</function> because different months have different numbers of
9771 days. <productname>PostgreSQL</productname>'s approach uses the month from the
9772 earlier of the two dates when calculating partial months. For example,
9773 <literal>age('2004-06-01', '2004-04-30')</literal> uses April to yield
9774 <literal>1 mon 1 day</literal>, while using May would yield <literal>1 mon 2
9775 days</literal> because May has 31 days, while April has only 30.
9776 </para>
9778 <para>
9779 Subtraction of dates and timestamps can also be complex. One conceptually
9780 simple way to perform subtraction is to convert each value to a number
9781 of seconds using <literal>EXTRACT(EPOCH FROM ...)</literal>, then subtract the
9782 results; this produces the
9783 number of <emphasis>seconds</emphasis> between the two values. This will adjust
9784 for the number of days in each month, timezone changes, and daylight
9785 saving time adjustments. Subtraction of date or timestamp
9786 values with the <quote><literal>-</literal></quote> operator
9787 returns the number of days (24-hours) and hours/minutes/seconds
9788 between the values, making the same adjustments. The <function>age</function>
9789 function returns years, months, days, and hours/minutes/seconds,
9790 performing field-by-field subtraction and then adjusting for negative
9791 field values. The following queries illustrate the differences in these
9792 approaches. The sample results were produced with <literal>timezone
9793 = 'US/Eastern'</literal>; there is a daylight saving time change between the
9794 two dates used:
9795 </para>
9797 <screen>
9798 SELECT EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
9799 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00');
9800 <lineannotation>Result: </lineannotation><computeroutput>10537200</computeroutput>
9801 SELECT (EXTRACT(EPOCH FROM timestamptz '2013-07-01 12:00:00') -
9802 EXTRACT(EPOCH FROM timestamptz '2013-03-01 12:00:00'))
9803 / 60 / 60 / 24;
9804 <lineannotation>Result: </lineannotation><computeroutput>121.958333333333</computeroutput>
9805 SELECT timestamptz '2013-07-01 12:00:00' - timestamptz '2013-03-01 12:00:00';
9806 <lineannotation>Result: </lineannotation><computeroutput>121 days 23:00:00</computeroutput>
9807 SELECT age(timestamptz '2013-07-01 12:00:00', timestamptz '2013-03-01 12:00:00');
9808 <lineannotation>Result: </lineannotation><computeroutput>4 mons</computeroutput>
9809 </screen>
9811 <sect2 id="functions-datetime-extract">
9812 <title><function>EXTRACT</function>, <function>date_part</function></title>
9814 <indexterm>
9815 <primary>date_part</primary>
9816 </indexterm>
9817 <indexterm>
9818 <primary>extract</primary>
9819 </indexterm>
9821 <synopsis>
9822 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
9823 </synopsis>
9825 <para>
9826 The <function>extract</function> function retrieves subfields
9827 such as year or hour from date/time values.
9828 <replaceable>source</replaceable> must be a value expression of
9829 type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
9830 (Expressions of type <type>date</type> are
9831 cast to <type>timestamp</type> and can therefore be used as
9832 well.) <replaceable>field</replaceable> is an identifier or
9833 string that selects what field to extract from the source value.
9834 The <function>extract</function> function returns values of type
9835 <type>numeric</type>.
9836 The following are valid field names:
9838 <!-- alphabetical -->
9839 <variablelist>
9840 <varlistentry>
9841 <term><literal>century</literal></term>
9842 <listitem>
9843 <para>
9844 The century
9845 </para>
9847 <screen>
9848 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
9849 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
9850 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
9851 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
9852 </screen>
9854 <para>
9855 The first century starts at 0001-01-01 00:00:00 AD, although
9856 they did not know it at the time. This definition applies to all
9857 Gregorian calendar countries. There is no century number 0,
9858 you go from -1 century to 1 century.
9860 If you disagree with this, please write your complaint to:
9861 Pope, Cathedral Saint-Peter of Roma, Vatican.
9862 </para>
9863 </listitem>
9864 </varlistentry>
9866 <varlistentry>
9867 <term><literal>day</literal></term>
9868 <listitem>
9869 <para>
9870 For <type>timestamp</type> values, the day (of the month) field
9871 (1&ndash;31) ; for <type>interval</type> values, the number of days
9872 </para>
9874 <screen>
9875 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
9876 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
9878 SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
9879 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
9880 </screen>
9882 </listitem>
9883 </varlistentry>
9885 <varlistentry>
9886 <term><literal>decade</literal></term>
9887 <listitem>
9888 <para>
9889 The year field divided by 10
9890 </para>
9892 <screen>
9893 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
9894 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
9895 </screen>
9896 </listitem>
9897 </varlistentry>
9899 <varlistentry>
9900 <term><literal>dow</literal></term>
9901 <listitem>
9902 <para>
9903 The day of the week as Sunday (<literal>0</literal>) to
9904 Saturday (<literal>6</literal>)
9905 </para>
9907 <screen>
9908 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
9909 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
9910 </screen>
9911 <para>
9912 Note that <function>extract</function>'s day of the week numbering
9913 differs from that of the <function>to_char(...,
9914 'D')</function> function.
9915 </para>
9917 </listitem>
9918 </varlistentry>
9920 <varlistentry>
9921 <term><literal>doy</literal></term>
9922 <listitem>
9923 <para>
9924 The day of the year (1&ndash;365/366)
9925 </para>
9927 <screen>
9928 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
9929 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
9930 </screen>
9931 </listitem>
9932 </varlistentry>
9934 <varlistentry>
9935 <term><literal>epoch</literal></term>
9936 <listitem>
9937 <para>
9938 For <type>timestamp with time zone</type> values, the
9939 number of seconds since 1970-01-01 00:00:00 UTC (negative for
9940 timestamps before that);
9941 for <type>date</type> and <type>timestamp</type> values, the
9942 nominal number of seconds since 1970-01-01 00:00:00,
9943 without regard to timezone or daylight-savings rules;
9944 for <type>interval</type> values, the total number
9945 of seconds in the interval
9946 </para>
9948 <screen>
9949 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
9950 <lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
9952 SELECT EXTRACT(EPOCH FROM TIMESTAMP '2001-02-16 20:38:40.12');
9953 <lineannotation>Result: </lineannotation><computeroutput>982355920.12</computeroutput>
9955 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
9956 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
9957 </screen>
9959 <para>
9960 You can convert an epoch value back to a <type>timestamp with time zone</type>
9961 with <function>to_timestamp</function>:
9962 </para>
9963 <screen>
9964 SELECT to_timestamp(982384720.12);
9965 <lineannotation>Result: </lineannotation><computeroutput>2001-02-17 04:38:40.12+00</computeroutput>
9966 </screen>
9968 <para>
9969 Beware that applying <function>to_timestamp</function> to an epoch
9970 extracted from a <type>date</type> or <type>timestamp</type> value
9971 could produce a misleading result: the result will effectively
9972 assume that the original value had been given in UTC, which might
9973 not be the case.
9974 </para>
9975 </listitem>
9976 </varlistentry>
9978 <varlistentry>
9979 <term><literal>hour</literal></term>
9980 <listitem>
9981 <para>
9982 The hour field (0&ndash;23)
9983 </para>
9985 <screen>
9986 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
9987 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
9988 </screen>
9989 </listitem>
9990 </varlistentry>
9992 <varlistentry>
9993 <term><literal>isodow</literal></term>
9994 <listitem>
9995 <para>
9996 The day of the week as Monday (<literal>1</literal>) to
9997 Sunday (<literal>7</literal>)
9998 </para>
10000 <screen>
10001 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
10002 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10003 </screen>
10004 <para>
10005 This is identical to <literal>dow</literal> except for Sunday. This
10006 matches the <acronym>ISO</acronym> 8601 day of the week numbering.
10007 </para>
10009 </listitem>
10010 </varlistentry>
10012 <varlistentry>
10013 <term><literal>isoyear</literal></term>
10014 <listitem>
10015 <para>
10016 The <acronym>ISO</acronym> 8601 week-numbering year that the date
10017 falls in (not applicable to intervals)
10018 </para>
10020 <screen>
10021 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
10022 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
10023 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
10024 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
10025 </screen>
10027 <para>
10028 Each <acronym>ISO</acronym> 8601 week-numbering year begins with the
10029 Monday of the week containing the 4th of January, so in early
10030 January or late December the <acronym>ISO</acronym> year may be
10031 different from the Gregorian year. See the <literal>week</literal>
10032 field for more information.
10033 </para>
10034 <para>
10035 This field is not available in PostgreSQL releases prior to 8.3.
10036 </para>
10037 </listitem>
10038 </varlistentry>
10040 <varlistentry>
10041 <term><literal>julian</literal></term>
10042 <listitem>
10043 <para>
10044 The <firstterm>Julian Date</firstterm> corresponding to the
10045 date or timestamp (not applicable to intervals). Timestamps
10046 that are not local midnight result in a fractional value. See
10047 <xref linkend="datetime-julian-dates"/> for more information.
10048 </para>
10050 <screen>
10051 SELECT EXTRACT(JULIAN FROM DATE '2006-01-01');
10052 <lineannotation>Result: </lineannotation><computeroutput>2453737</computeroutput>
10053 SELECT EXTRACT(JULIAN FROM TIMESTAMP '2006-01-01 12:00');
10054 <lineannotation>Result: </lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
10055 </screen>
10056 </listitem>
10057 </varlistentry>
10059 <varlistentry>
10060 <term><literal>microseconds</literal></term>
10061 <listitem>
10062 <para>
10063 The seconds field, including fractional parts, multiplied by 1
10064 000 000; note that this includes full seconds
10065 </para>
10067 <screen>
10068 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
10069 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
10070 </screen>
10071 </listitem>
10072 </varlistentry>
10074 <varlistentry>
10075 <term><literal>millennium</literal></term>
10076 <listitem>
10077 <para>
10078 The millennium
10079 </para>
10081 <screen>
10082 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
10083 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10084 </screen>
10086 <para>
10087 Years in the 1900s are in the second millennium.
10088 The third millennium started January 1, 2001.
10089 </para>
10090 </listitem>
10091 </varlistentry>
10093 <varlistentry>
10094 <term><literal>milliseconds</literal></term>
10095 <listitem>
10096 <para>
10097 The seconds field, including fractional parts, multiplied by
10098 1000. Note that this includes full seconds.
10099 </para>
10101 <screen>
10102 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
10103 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
10104 </screen>
10105 </listitem>
10106 </varlistentry>
10108 <varlistentry>
10109 <term><literal>minute</literal></term>
10110 <listitem>
10111 <para>
10112 The minutes field (0&ndash;59)
10113 </para>
10115 <screen>
10116 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
10117 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
10118 </screen>
10119 </listitem>
10120 </varlistentry>
10122 <varlistentry>
10123 <term><literal>month</literal></term>
10124 <listitem>
10125 <para>
10126 For <type>timestamp</type> values, the number of the month
10127 within the year (1&ndash;12) ; for <type>interval</type> values,
10128 the number of months, modulo 12 (0&ndash;11)
10129 </para>
10131 <screen>
10132 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
10133 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
10135 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
10136 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
10138 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
10139 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10140 </screen>
10141 </listitem>
10142 </varlistentry>
10144 <varlistentry>
10145 <term><literal>quarter</literal></term>
10146 <listitem>
10147 <para>
10148 The quarter of the year (1&ndash;4) that the date is in
10149 </para>
10151 <screen>
10152 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
10153 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
10154 </screen>
10155 </listitem>
10156 </varlistentry>
10158 <varlistentry>
10159 <term><literal>second</literal></term>
10160 <listitem>
10161 <para>
10162 The seconds field, including any fractional seconds
10163 </para>
10165 <screen>
10166 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
10167 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
10169 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
10170 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
10171 </screen>
10172 </listitem>
10173 </varlistentry>
10174 <varlistentry>
10175 <term><literal>timezone</literal></term>
10176 <listitem>
10177 <para>
10178 The time zone offset from UTC, measured in seconds. Positive values
10179 correspond to time zones east of UTC, negative values to
10180 zones west of UTC. (Technically,
10181 <productname>PostgreSQL</productname> does not use UTC because
10182 leap seconds are not handled.)
10183 </para>
10184 </listitem>
10185 </varlistentry>
10187 <varlistentry>
10188 <term><literal>timezone_hour</literal></term>
10189 <listitem>
10190 <para>
10191 The hour component of the time zone offset
10192 </para>
10193 </listitem>
10194 </varlistentry>
10196 <varlistentry>
10197 <term><literal>timezone_minute</literal></term>
10198 <listitem>
10199 <para>
10200 The minute component of the time zone offset
10201 </para>
10202 </listitem>
10203 </varlistentry>
10205 <varlistentry>
10206 <term><literal>week</literal></term>
10207 <listitem>
10208 <para>
10209 The number of the <acronym>ISO</acronym> 8601 week-numbering week of
10210 the year. By definition, ISO weeks start on Mondays and the first
10211 week of a year contains January 4 of that year. In other words, the
10212 first Thursday of a year is in week 1 of that year.
10213 </para>
10214 <para>
10215 In the ISO week-numbering system, it is possible for early-January
10216 dates to be part of the 52nd or 53rd week of the previous year, and for
10217 late-December dates to be part of the first week of the next year.
10218 For example, <literal>2005-01-01</literal> is part of the 53rd week of year
10219 2004, and <literal>2006-01-01</literal> is part of the 52nd week of year
10220 2005, while <literal>2012-12-31</literal> is part of the first week of 2013.
10221 It's recommended to use the <literal>isoyear</literal> field together with
10222 <literal>week</literal> to get consistent results.
10223 </para>
10225 <screen>
10226 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
10227 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
10228 </screen>
10229 </listitem>
10230 </varlistentry>
10232 <varlistentry>
10233 <term><literal>year</literal></term>
10234 <listitem>
10235 <para>
10236 The year field. Keep in mind there is no <literal>0 AD</literal>, so subtracting
10237 <literal>BC</literal> years from <literal>AD</literal> years should be done with care.
10238 </para>
10240 <screen>
10241 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
10242 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
10243 </screen>
10244 </listitem>
10245 </varlistentry>
10247 </variablelist>
10248 </para>
10250 <note>
10251 <para>
10252 When the input value is +/-Infinity, <function>extract</function> returns
10253 +/-Infinity for monotonically-increasing fields (<literal>epoch</literal>,
10254 <literal>julian</literal>, <literal>year</literal>, <literal>isoyear</literal>,
10255 <literal>decade</literal>, <literal>century</literal>, and <literal>millennium</literal>).
10256 For other fields, NULL is returned. <productname>PostgreSQL</productname>
10257 versions before 9.6 returned zero for all cases of infinite input.
10258 </para>
10259 </note>
10261 <para>
10262 The <function>extract</function> function is primarily intended
10263 for computational processing. For formatting date/time values for
10264 display, see <xref linkend="functions-formatting"/>.
10265 </para>
10267 <para>
10268 The <function>date_part</function> function is modeled on the traditional
10269 <productname>Ingres</productname> equivalent to the
10270 <acronym>SQL</acronym>-standard function <function>extract</function>:
10271 <synopsis>
10272 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
10273 </synopsis>
10274 Note that here the <replaceable>field</replaceable> parameter needs to
10275 be a string value, not a name. The valid field names for
10276 <function>date_part</function> are the same as for
10277 <function>extract</function>.
10278 For historical reasons, the <function>date_part</function> function
10279 returns values of type <type>double precision</type>. This can result in
10280 a loss of precision in certain uses. Using <function>extract</function>
10281 is recommended instead.
10282 </para>
10284 <screen>
10285 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
10286 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
10288 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
10289 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
10290 </screen>
10292 </sect2>
10294 <sect2 id="functions-datetime-trunc">
10295 <title><function>date_trunc</function></title>
10297 <indexterm>
10298 <primary>date_trunc</primary>
10299 </indexterm>
10301 <para>
10302 The function <function>date_trunc</function> is conceptually
10303 similar to the <function>trunc</function> function for numbers.
10304 </para>
10306 <para>
10307 <synopsis>
10308 date_trunc(<replaceable>field</replaceable>, <replaceable>source</replaceable> [, <replaceable>time_zone</replaceable> ])
10309 </synopsis>
10310 <replaceable>source</replaceable> is a value expression of type
10311 <type>timestamp</type>, <type>timestamp with time zone</type>,
10312 or <type>interval</type>.
10313 (Values of type <type>date</type> and
10314 <type>time</type> are cast automatically to <type>timestamp</type> or
10315 <type>interval</type>, respectively.)
10316 <replaceable>field</replaceable> selects to which precision to
10317 truncate the input value. The return value is likewise of type
10318 <type>timestamp</type>, <type>timestamp with time zone</type>,
10319 or <type>interval</type>,
10320 and it has all fields that are less significant than the
10321 selected one set to zero (or one, for day and month).
10322 </para>
10324 <para>
10325 Valid values for <replaceable>field</replaceable> are:
10326 <simplelist>
10327 <member><literal>microseconds</literal></member>
10328 <member><literal>milliseconds</literal></member>
10329 <member><literal>second</literal></member>
10330 <member><literal>minute</literal></member>
10331 <member><literal>hour</literal></member>
10332 <member><literal>day</literal></member>
10333 <member><literal>week</literal></member>
10334 <member><literal>month</literal></member>
10335 <member><literal>quarter</literal></member>
10336 <member><literal>year</literal></member>
10337 <member><literal>decade</literal></member>
10338 <member><literal>century</literal></member>
10339 <member><literal>millennium</literal></member>
10340 </simplelist>
10341 </para>
10343 <para>
10344 When the input value is of type <type>timestamp with time zone</type>,
10345 the truncation is performed with respect to a particular time zone;
10346 for example, truncation to <literal>day</literal> produces a value that
10347 is midnight in that zone. By default, truncation is done with respect
10348 to the current <xref linkend="guc-timezone"/> setting, but the
10349 optional <replaceable>time_zone</replaceable> argument can be provided
10350 to specify a different time zone. The time zone name can be specified
10351 in any of the ways described in <xref linkend="datatype-timezones"/>.
10352 </para>
10354 <para>
10355 A time zone cannot be specified when processing <type>timestamp without
10356 time zone</type> or <type>interval</type> inputs. These are always
10357 taken at face value.
10358 </para>
10360 <para>
10361 Examples (assuming the local time zone is <literal>America/New_York</literal>):
10362 <screen>
10363 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
10364 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
10366 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
10367 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
10369 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00');
10370 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 00:00:00-05</computeroutput>
10372 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40+00', 'Australia/Sydney');
10373 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 08:00:00-05</computeroutput>
10375 SELECT date_trunc('hour', INTERVAL '3 days 02:47:33');
10376 <lineannotation>Result: </lineannotation><computeroutput>3 days 02:00:00</computeroutput>
10377 </screen>
10378 </para>
10379 </sect2>
10381 <sect2 id="functions-datetime-bin">
10382 <title><function>date_bin</function></title>
10384 <indexterm>
10385 <primary>date_bin</primary>
10386 </indexterm>
10388 <para>
10389 The function <function>date_bin</function> <quote>bins</quote> the input
10390 timestamp into the specified interval (the <firstterm>stride</firstterm>)
10391 aligned with a specified origin.
10392 </para>
10394 <para>
10395 <synopsis>
10396 date_bin(<replaceable>stride</replaceable>, <replaceable>source</replaceable>, <replaceable>origin</replaceable>)
10397 </synopsis>
10398 <replaceable>source</replaceable> is a value expression of type
10399 <type>timestamp</type> or <type>timestamp with time zone</type>. (Values
10400 of type <type>date</type> are cast automatically to
10401 <type>timestamp</type>.) <replaceable>stride</replaceable> is a value
10402 expression of type <type>interval</type>. The return value is likewise
10403 of type <type>timestamp</type> or <type>timestamp with time zone</type>,
10404 and it marks the beginning of the bin into which the
10405 <replaceable>source</replaceable> is placed.
10406 </para>
10408 <para>
10409 Examples:
10410 <screen>
10411 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01');
10412 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:30:00</computeroutput>
10414 SELECT date_bin('15 minutes', TIMESTAMP '2020-02-11 15:44:17', TIMESTAMP '2001-01-01 00:02:30');
10415 <lineannotation>Result: </lineannotation><computeroutput>2020-02-11 15:32:30</computeroutput>
10416 </screen>
10417 </para>
10419 <para>
10420 In the case of full units (1 minute, 1 hour, etc.), it gives the same result as
10421 the analogous <function>date_trunc</function> call, but the difference is
10422 that <function>date_bin</function> can truncate to an arbitrary interval.
10423 </para>
10425 <para>
10426 The <parameter>stride</parameter> interval must be greater than zero and
10427 cannot contain units of month or larger.
10428 </para>
10429 </sect2>
10431 <sect2 id="functions-datetime-zoneconvert">
10432 <title><literal>AT TIME ZONE</literal></title>
10434 <indexterm>
10435 <primary>time zone</primary>
10436 <secondary>conversion</secondary>
10437 </indexterm>
10439 <indexterm>
10440 <primary>AT TIME ZONE</primary>
10441 </indexterm>
10443 <para>
10444 The <literal>AT TIME ZONE</literal> operator converts time
10445 stamp <emphasis>without</emphasis> time zone to/from
10446 time stamp <emphasis>with</emphasis> time zone, and
10447 <type>time with time zone</type> values to different time
10448 zones. <xref linkend="functions-datetime-zoneconvert-table"/> shows its
10449 variants.
10450 </para>
10452 <table id="functions-datetime-zoneconvert-table">
10453 <title><literal>AT TIME ZONE</literal> Variants</title>
10454 <tgroup cols="1">
10455 <thead>
10456 <row>
10457 <entry role="func_table_entry"><para role="func_signature">
10458 Operator
10459 </para>
10460 <para>
10461 Description
10462 </para>
10463 <para>
10464 Example(s)
10465 </para></entry>
10466 </row>
10467 </thead>
10469 <tbody>
10470 <row>
10471 <entry role="func_table_entry"><para role="func_signature">
10472 <type>timestamp without time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10473 <returnvalue>timestamp with time zone</returnvalue>
10474 </para>
10475 <para>
10476 Converts given time stamp <emphasis>without</emphasis> time zone to
10477 time stamp <emphasis>with</emphasis> time zone, assuming the given
10478 value is in the named time zone.
10479 </para>
10480 <para>
10481 <literal>timestamp '2001-02-16 20:38:40' at time zone 'America/Denver'</literal>
10482 <returnvalue>2001-02-17 03:38:40+00</returnvalue>
10483 </para></entry>
10484 </row>
10486 <row>
10487 <entry role="func_table_entry"><para role="func_signature">
10488 <type>timestamp with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10489 <returnvalue>timestamp without time zone</returnvalue>
10490 </para>
10491 <para>
10492 Converts given time stamp <emphasis>with</emphasis> time zone to
10493 time stamp <emphasis>without</emphasis> time zone, as the time would
10494 appear in that zone.
10495 </para>
10496 <para>
10497 <literal>timestamp with time zone '2001-02-16 20:38:40-05' at time zone 'America/Denver'</literal>
10498 <returnvalue>2001-02-16 18:38:40</returnvalue>
10499 </para></entry>
10500 </row>
10502 <row>
10503 <entry role="func_table_entry"><para role="func_signature">
10504 <type>time with time zone</type> <literal>AT TIME ZONE</literal> <replaceable>zone</replaceable>
10505 <returnvalue>time with time zone</returnvalue>
10506 </para>
10507 <para>
10508 Converts given time <emphasis>with</emphasis> time zone to a new time
10509 zone. Since no date is supplied, this uses the currently active UTC
10510 offset for the named destination zone.
10511 </para>
10512 <para>
10513 <literal>time with time zone '05:34:17-05' at time zone 'UTC'</literal>
10514 <returnvalue>10:34:17+00</returnvalue>
10515 </para></entry>
10516 </row>
10517 </tbody>
10518 </tgroup>
10519 </table>
10521 <para>
10522 In these expressions, the desired time zone <replaceable>zone</replaceable> can be
10523 specified either as a text value (e.g., <literal>'America/Los_Angeles'</literal>)
10524 or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
10525 In the text case, a time zone name can be specified in any of the ways
10526 described in <xref linkend="datatype-timezones"/>.
10527 The interval case is only useful for zones that have fixed offsets from
10528 UTC, so it is not very common in practice.
10529 </para>
10531 <para>
10532 Examples (assuming the current <xref linkend="guc-timezone"/> setting
10533 is <literal>America/Los_Angeles</literal>):
10534 <screen>
10535 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'America/Denver';
10536 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
10538 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'America/Denver';
10539 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
10541 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
10542 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 05:38:40</computeroutput>
10543 </screen>
10544 The first example adds a time zone to a value that lacks it, and
10545 displays the value using the current <varname>TimeZone</varname>
10546 setting. The second example shifts the time stamp with time zone value
10547 to the specified time zone, and returns the value without a time zone.
10548 This allows storage and display of values different from the current
10549 <varname>TimeZone</varname> setting. The third example converts
10550 Tokyo time to Chicago time.
10551 </para>
10553 <para>
10554 The function <literal><function>timezone</function>(<replaceable>zone</replaceable>,
10555 <replaceable>timestamp</replaceable>)</literal> is equivalent to the SQL-conforming construct
10556 <literal><replaceable>timestamp</replaceable> AT TIME ZONE
10557 <replaceable>zone</replaceable></literal>.
10558 </para>
10559 </sect2>
10561 <sect2 id="functions-datetime-current">
10562 <title>Current Date/Time</title>
10564 <indexterm>
10565 <primary>date</primary>
10566 <secondary>current</secondary>
10567 </indexterm>
10569 <indexterm>
10570 <primary>time</primary>
10571 <secondary>current</secondary>
10572 </indexterm>
10574 <para>
10575 <productname>PostgreSQL</productname> provides a number of functions
10576 that return values related to the current date and time. These
10577 SQL-standard functions all return values based on the start time of
10578 the current transaction:
10579 <synopsis>
10580 CURRENT_DATE
10581 CURRENT_TIME
10582 CURRENT_TIMESTAMP
10583 CURRENT_TIME(<replaceable>precision</replaceable>)
10584 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
10585 LOCALTIME
10586 LOCALTIMESTAMP
10587 LOCALTIME(<replaceable>precision</replaceable>)
10588 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
10589 </synopsis>
10590 </para>
10592 <para>
10593 <function>CURRENT_TIME</function> and
10594 <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
10595 <function>LOCALTIME</function> and
10596 <function>LOCALTIMESTAMP</function> deliver values without time zone.
10597 </para>
10599 <para>
10600 <function>CURRENT_TIME</function>,
10601 <function>CURRENT_TIMESTAMP</function>,
10602 <function>LOCALTIME</function>, and
10603 <function>LOCALTIMESTAMP</function>
10604 can optionally take
10605 a precision parameter, which causes the result to be rounded
10606 to that many fractional digits in the seconds field. Without a precision parameter,
10607 the result is given to the full available precision.
10608 </para>
10610 <para>
10611 Some examples:
10612 <screen>
10613 SELECT CURRENT_TIME;
10614 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
10616 SELECT CURRENT_DATE;
10617 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23</computeroutput>
10619 SELECT CURRENT_TIMESTAMP;
10620 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522-05</computeroutput>
10622 SELECT CURRENT_TIMESTAMP(2);
10623 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.66-05</computeroutput>
10625 SELECT LOCALTIMESTAMP;
10626 <lineannotation>Result: </lineannotation><computeroutput>2019-12-23 14:39:53.662522</computeroutput>
10627 </screen>
10628 </para>
10630 <para>
10631 Since these functions return
10632 the start time of the current transaction, their values do not
10633 change during the transaction. This is considered a feature:
10634 the intent is to allow a single transaction to have a consistent
10635 notion of the <quote>current</quote> time, so that multiple
10636 modifications within the same transaction bear the same
10637 time stamp.
10638 </para>
10640 <note>
10641 <para>
10642 Other database systems might advance these values more
10643 frequently.
10644 </para>
10645 </note>
10647 <para>
10648 <productname>PostgreSQL</productname> also provides functions that
10649 return the start time of the current statement, as well as the actual
10650 current time at the instant the function is called. The complete list
10651 of non-SQL-standard time functions is:
10652 <synopsis>
10653 transaction_timestamp()
10654 statement_timestamp()
10655 clock_timestamp()
10656 timeofday()
10657 now()
10658 </synopsis>
10659 </para>
10661 <para>
10662 <function>transaction_timestamp()</function> is equivalent to
10663 <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
10664 what it returns.
10665 <function>statement_timestamp()</function> returns the start time of the current
10666 statement (more specifically, the time of receipt of the latest command
10667 message from the client).
10668 <function>statement_timestamp()</function> and <function>transaction_timestamp()</function>
10669 return the same value during the first command of a transaction, but might
10670 differ during subsequent commands.
10671 <function>clock_timestamp()</function> returns the actual current time, and
10672 therefore its value changes even within a single SQL command.
10673 <function>timeofday()</function> is a historical
10674 <productname>PostgreSQL</productname> function. Like
10675 <function>clock_timestamp()</function>, it returns the actual current time,
10676 but as a formatted <type>text</type> string rather than a <type>timestamp
10677 with time zone</type> value.
10678 <function>now()</function> is a traditional <productname>PostgreSQL</productname>
10679 equivalent to <function>transaction_timestamp()</function>.
10680 </para>
10682 <para>
10683 All the date/time data types also accept the special literal value
10684 <literal>now</literal> to specify the current date and time (again,
10685 interpreted as the transaction start time). Thus,
10686 the following three all return the same result:
10687 <programlisting>
10688 SELECT CURRENT_TIMESTAMP;
10689 SELECT now();
10690 SELECT TIMESTAMP 'now'; -- but see tip below
10691 </programlisting>
10692 </para>
10694 <tip>
10695 <para>
10696 Do not use the third form when specifying a value to be evaluated later,
10697 for example in a <literal>DEFAULT</literal> clause for a table column.
10698 The system will convert <literal>now</literal>
10699 to a <type>timestamp</type> as soon as the constant is parsed, so that when
10700 the default value is needed,
10701 the time of the table creation would be used! The first two
10702 forms will not be evaluated until the default value is used,
10703 because they are function calls. Thus they will give the desired
10704 behavior of defaulting to the time of row insertion.
10705 (See also <xref linkend="datatype-datetime-special-values"/>.)
10706 </para>
10707 </tip>
10708 </sect2>
10710 <sect2 id="functions-datetime-delay">
10711 <title>Delaying Execution</title>
10713 <indexterm>
10714 <primary>pg_sleep</primary>
10715 </indexterm>
10716 <indexterm>
10717 <primary>pg_sleep_for</primary>
10718 </indexterm>
10719 <indexterm>
10720 <primary>pg_sleep_until</primary>
10721 </indexterm>
10722 <indexterm>
10723 <primary>sleep</primary>
10724 </indexterm>
10725 <indexterm>
10726 <primary>delay</primary>
10727 </indexterm>
10729 <para>
10730 The following functions are available to delay execution of the server
10731 process:
10732 <synopsis>
10733 pg_sleep ( <type>double precision</type> )
10734 pg_sleep_for ( <type>interval</type> )
10735 pg_sleep_until ( <type>timestamp with time zone</type> )
10736 </synopsis>
10738 <function>pg_sleep</function> makes the current session's process
10739 sleep until the given number of seconds have
10740 elapsed. Fractional-second delays can be specified.
10741 <function>pg_sleep_for</function> is a convenience function to
10742 allow the sleep time to be specified as an <type>interval</type>.
10743 <function>pg_sleep_until</function> is a convenience function for when
10744 a specific wake-up time is desired.
10745 For example:
10747 <programlisting>
10748 SELECT pg_sleep(1.5);
10749 SELECT pg_sleep_for('5 minutes');
10750 SELECT pg_sleep_until('tomorrow 03:00');
10751 </programlisting>
10752 </para>
10754 <note>
10755 <para>
10756 The effective resolution of the sleep interval is platform-specific;
10757 0.01 seconds is a common value. The sleep delay will be at least as long
10758 as specified. It might be longer depending on factors such as server load.
10759 In particular, <function>pg_sleep_until</function> is not guaranteed to
10760 wake up exactly at the specified time, but it will not wake up any earlier.
10761 </para>
10762 </note>
10764 <warning>
10765 <para>
10766 Make sure that your session does not hold more locks than necessary
10767 when calling <function>pg_sleep</function> or its variants. Otherwise
10768 other sessions might have to wait for your sleeping process, slowing down
10769 the entire system.
10770 </para>
10771 </warning>
10772 </sect2>
10774 </sect1>
10777 <sect1 id="functions-enum">
10778 <title>Enum Support Functions</title>
10780 <para>
10781 For enum types (described in <xref linkend="datatype-enum"/>),
10782 there are several functions that allow cleaner programming without
10783 hard-coding particular values of an enum type.
10784 These are listed in <xref linkend="functions-enum-table"/>. The examples
10785 assume an enum type created as:
10787 <programlisting>
10788 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
10789 </programlisting>
10791 </para>
10793 <table id="functions-enum-table">
10794 <title>Enum Support Functions</title>
10795 <tgroup cols="1">
10796 <thead>
10797 <row>
10798 <entry role="func_table_entry"><para role="func_signature">
10799 Function
10800 </para>
10801 <para>
10802 Description
10803 </para>
10804 <para>
10805 Example(s)
10806 </para></entry>
10807 </row>
10808 </thead>
10810 <tbody>
10811 <row>
10812 <entry role="func_table_entry"><para role="func_signature">
10813 <indexterm>
10814 <primary>enum_first</primary>
10815 </indexterm>
10816 <function>enum_first</function> ( <type>anyenum</type> )
10817 <returnvalue>anyenum</returnvalue>
10818 </para>
10819 <para>
10820 Returns the first value of the input enum type.
10821 </para>
10822 <para>
10823 <literal>enum_first(null::rainbow)</literal>
10824 <returnvalue>red</returnvalue>
10825 </para></entry>
10826 </row>
10827 <row>
10828 <entry role="func_table_entry"><para role="func_signature">
10829 <indexterm>
10830 <primary>enum_last</primary>
10831 </indexterm>
10832 <function>enum_last</function> ( <type>anyenum</type> )
10833 <returnvalue>anyenum</returnvalue>
10834 </para>
10835 <para>
10836 Returns the last value of the input enum type.
10837 </para>
10838 <para>
10839 <literal>enum_last(null::rainbow)</literal>
10840 <returnvalue>purple</returnvalue>
10841 </para></entry>
10842 </row>
10843 <row>
10844 <entry role="func_table_entry"><para role="func_signature">
10845 <indexterm>
10846 <primary>enum_range</primary>
10847 </indexterm>
10848 <function>enum_range</function> ( <type>anyenum</type> )
10849 <returnvalue>anyarray</returnvalue>
10850 </para>
10851 <para>
10852 Returns all values of the input enum type in an ordered array.
10853 </para>
10854 <para>
10855 <literal>enum_range(null::rainbow)</literal>
10856 <returnvalue>{red,orange,yellow,&zwsp;green,blue,purple}</returnvalue>
10857 </para></entry>
10858 </row>
10859 <row>
10860 <entry role="func_table_entry"><para role="func_signature">
10861 <function>enum_range</function> ( <type>anyenum</type>, <type>anyenum</type> )
10862 <returnvalue>anyarray</returnvalue>
10863 </para>
10864 <para>
10865 Returns the range between the two given enum values, as an ordered
10866 array. The values must be from the same enum type. If the first
10867 parameter is null, the result will start with the first value of
10868 the enum type.
10869 If the second parameter is null, the result will end with the last
10870 value of the enum type.
10871 </para>
10872 <para>
10873 <literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal>
10874 <returnvalue>{orange,yellow,green}</returnvalue>
10875 </para>
10876 <para>
10877 <literal>enum_range(NULL, 'green'::rainbow)</literal>
10878 <returnvalue>{red,orange,&zwsp;yellow,green}</returnvalue>
10879 </para>
10880 <para>
10881 <literal>enum_range('orange'::rainbow, NULL)</literal>
10882 <returnvalue>{orange,yellow,green,&zwsp;blue,purple}</returnvalue>
10883 </para></entry>
10884 </row>
10885 </tbody>
10886 </tgroup>
10887 </table>
10889 <para>
10890 Notice that except for the two-argument form of <function>enum_range</function>,
10891 these functions disregard the specific value passed to them; they care
10892 only about its declared data type. Either null or a specific value of
10893 the type can be passed, with the same result. It is more common to
10894 apply these functions to a table column or function argument than to
10895 a hardwired type name as used in the examples.
10896 </para>
10897 </sect1>
10899 <sect1 id="functions-geometry">
10900 <title>Geometric Functions and Operators</title>
10902 <para>
10903 The geometric types <type>point</type>, <type>box</type>,
10904 <type>lseg</type>, <type>line</type>, <type>path</type>,
10905 <type>polygon</type>, and <type>circle</type> have a large set of
10906 native support functions and operators, shown in <xref
10907 linkend="functions-geometry-op-table"/>, <xref
10908 linkend="functions-geometry-func-table"/>, and <xref
10909 linkend="functions-geometry-conv-table"/>.
10910 </para>
10912 <table id="functions-geometry-op-table">
10913 <title>Geometric Operators</title>
10914 <tgroup cols="1">
10915 <thead>
10916 <row>
10917 <entry role="func_table_entry"><para role="func_signature">
10918 Operator
10919 </para>
10920 <para>
10921 Description
10922 </para>
10923 <para>
10924 Example(s)
10925 </para></entry>
10926 </row>
10927 </thead>
10929 <tbody>
10930 <row>
10931 <entry role="func_table_entry"><para role="func_signature">
10932 <replaceable>geometric_type</replaceable> <literal>+</literal> <type>point</type>
10933 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
10934 </para>
10935 <para>
10936 Adds the coordinates of the second <type>point</type> to those of each
10937 point of the first argument, thus performing translation.
10938 Available for <type>point</type>, <type>box</type>, <type>path</type>,
10939 <type>circle</type>.
10940 </para>
10941 <para>
10942 <literal>box '(1,1),(0,0)' + point '(2,0)'</literal>
10943 <returnvalue>(3,1),(2,0)</returnvalue>
10944 </para></entry>
10945 </row>
10947 <row>
10948 <entry role="func_table_entry"><para role="func_signature">
10949 <type>path</type> <literal>+</literal> <type>path</type>
10950 <returnvalue>path</returnvalue>
10951 </para>
10952 <para>
10953 Concatenates two open paths (returns NULL if either path is closed).
10954 </para>
10955 <para>
10956 <literal>path '[(0,0),(1,1)]' + path '[(2,2),(3,3),(4,4)]'</literal>
10957 <returnvalue>[(0,0),(1,1),(2,2),(3,3),(4,4)]</returnvalue>
10958 </para></entry>
10959 </row>
10961 <row>
10962 <entry role="func_table_entry"><para role="func_signature">
10963 <replaceable>geometric_type</replaceable> <literal>-</literal> <type>point</type>
10964 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
10965 </para>
10966 <para>
10967 Subtracts the coordinates of the second <type>point</type> from those
10968 of each point of the first argument, thus performing translation.
10969 Available for <type>point</type>, <type>box</type>, <type>path</type>,
10970 <type>circle</type>.
10971 </para>
10972 <para>
10973 <literal>box '(1,1),(0,0)' - point '(2,0)'</literal>
10974 <returnvalue>(-1,1),(-2,0)</returnvalue>
10975 </para></entry>
10976 </row>
10978 <row>
10979 <entry role="func_table_entry"><para role="func_signature">
10980 <replaceable>geometric_type</replaceable> <literal>*</literal> <type>point</type>
10981 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
10982 </para>
10983 <para>
10984 Multiplies each point of the first argument by the second
10985 <type>point</type> (treating a point as being a complex number
10986 represented by real and imaginary parts, and performing standard
10987 complex multiplication). If one interprets
10988 the second <type>point</type> as a vector, this is equivalent to
10989 scaling the object's size and distance from the origin by the length
10990 of the vector, and rotating it counterclockwise around the origin by
10991 the vector's angle from the <replaceable>x</replaceable> axis.
10992 Available for <type>point</type>, <type>box</type>,<footnote
10993 id="functions-geometry-rotation-fn"><para><quote>Rotating</quote> a
10994 box with these operators only moves its corner points: the box is
10995 still considered to have sides parallel to the axes. Hence the box's
10996 size is not preserved, as a true rotation would do.</para></footnote>
10997 <type>path</type>, <type>circle</type>.
10998 </para>
10999 <para>
11000 <literal>path '((0,0),(1,0),(1,1))' * point '(3.0,0)'</literal>
11001 <returnvalue>((0,0),(3,0),(3,3))</returnvalue>
11002 </para>
11003 <para>
11004 <literal>path '((0,0),(1,0),(1,1))' * point(cosd(45), sind(45))</literal>
11005 <returnvalue>((0,0),&zwsp;(0.7071067811865475,0.7071067811865475),&zwsp;(0,1.414213562373095))</returnvalue>
11006 </para></entry>
11007 </row>
11009 <row>
11010 <entry role="func_table_entry"><para role="func_signature">
11011 <replaceable>geometric_type</replaceable> <literal>/</literal> <type>point</type>
11012 <returnvalue><replaceable>geometric_type</replaceable></returnvalue>
11013 </para>
11014 <para>
11015 Divides each point of the first argument by the second
11016 <type>point</type> (treating a point as being a complex number
11017 represented by real and imaginary parts, and performing standard
11018 complex division). If one interprets
11019 the second <type>point</type> as a vector, this is equivalent to
11020 scaling the object's size and distance from the origin down by the
11021 length of the vector, and rotating it clockwise around the origin by
11022 the vector's angle from the <replaceable>x</replaceable> axis.
11023 Available for <type>point</type>, <type>box</type>,<footnoteref
11024 linkend="functions-geometry-rotation-fn"/> <type>path</type>,
11025 <type>circle</type>.
11026 </para>
11027 <para>
11028 <literal>path '((0,0),(1,0),(1,1))' / point '(2.0,0)'</literal>
11029 <returnvalue>((0,0),(0.5,0),(0.5,0.5))</returnvalue>
11030 </para>
11031 <para>
11032 <literal>path '((0,0),(1,0),(1,1))' / point(cosd(45), sind(45))</literal>
11033 <returnvalue>((0,0),&zwsp;(0.7071067811865476,-0.7071067811865476),&zwsp;(1.4142135623730951,0))</returnvalue>
11034 </para></entry>
11035 </row>
11037 <row>
11038 <entry role="func_table_entry"><para role="func_signature">
11039 <literal>@-@</literal> <replaceable>geometric_type</replaceable>
11040 <returnvalue>double precision</returnvalue>
11041 </para>
11042 <para>
11043 Computes the total length.
11044 Available for <type>lseg</type>, <type>path</type>.
11045 </para>
11046 <para>
11047 <literal>@-@ path '[(0,0),(1,0),(1,1)]'</literal>
11048 <returnvalue>2</returnvalue>
11049 </para></entry>
11050 </row>
11052 <row>
11053 <entry role="func_table_entry"><para role="func_signature">
11054 <literal>@@</literal> <replaceable>geometric_type</replaceable>
11055 <returnvalue>point</returnvalue>
11056 </para>
11057 <para>
11058 Computes the center point.
11059 Available for <type>box</type>, <type>lseg</type>,
11060 <type>polygon</type>, <type>circle</type>.
11061 </para>
11062 <para>
11063 <literal>@@ box '(2,2),(0,0)'</literal>
11064 <returnvalue>(1,1)</returnvalue>
11065 </para></entry>
11066 </row>
11068 <row>
11069 <entry role="func_table_entry"><para role="func_signature">
11070 <literal>#</literal> <replaceable>geometric_type</replaceable>
11071 <returnvalue>integer</returnvalue>
11072 </para>
11073 <para>
11074 Returns the number of points.
11075 Available for <type>path</type>, <type>polygon</type>.
11076 </para>
11077 <para>
11078 <literal># path '((1,0),(0,1),(-1,0))'</literal>
11079 <returnvalue>3</returnvalue>
11080 </para></entry>
11081 </row>
11083 <row>
11084 <entry role="func_table_entry"><para role="func_signature">
11085 <replaceable>geometric_type</replaceable> <literal>#</literal> <replaceable>geometric_type</replaceable>
11086 <returnvalue>point</returnvalue>
11087 </para>
11088 <para>
11089 Computes the point of intersection, or NULL if there is none.
11090 Available for <type>lseg</type>, <type>line</type>.
11091 </para>
11092 <para>
11093 <literal>lseg '[(0,0),(1,1)]' # lseg '[(1,0),(0,1)]'</literal>
11094 <returnvalue>(0.5,0.5)</returnvalue>
11095 </para></entry>
11096 </row>
11098 <row>
11099 <entry role="func_table_entry"><para role="func_signature">
11100 <type>box</type> <literal>#</literal> <type>box</type>
11101 <returnvalue>box</returnvalue>
11102 </para>
11103 <para>
11104 Computes the intersection of two boxes, or NULL if there is none.
11105 </para>
11106 <para>
11107 <literal>box '(2,2),(-1,-1)' # box '(1,1),(-2,-2)'</literal>
11108 <returnvalue>(1,1),(-1,-1)</returnvalue>
11109 </para></entry>
11110 </row>
11112 <row>
11113 <entry role="func_table_entry"><para role="func_signature">
11114 <replaceable>geometric_type</replaceable> <literal>##</literal> <replaceable>geometric_type</replaceable>
11115 <returnvalue>point</returnvalue>
11116 </para>
11117 <para>
11118 Computes the closest point to the first object on the second object.
11119 Available for these pairs of types:
11120 (<type>point</type>, <type>box</type>),
11121 (<type>point</type>, <type>lseg</type>),
11122 (<type>point</type>, <type>line</type>),
11123 (<type>lseg</type>, <type>box</type>),
11124 (<type>lseg</type>, <type>lseg</type>),
11125 (<type>line</type>, <type>lseg</type>).
11126 </para>
11127 <para>
11128 <literal>point '(0,0)' ## lseg '[(2,0),(0,2)]'</literal>
11129 <returnvalue>(1,1)</returnvalue>
11130 </para></entry>
11131 </row>
11133 <row>
11134 <entry role="func_table_entry"><para role="func_signature">
11135 <replaceable>geometric_type</replaceable> <literal>&lt;-&gt;</literal> <replaceable>geometric_type</replaceable>
11136 <returnvalue>double precision</returnvalue>
11137 </para>
11138 <para>
11139 Computes the distance between the objects.
11140 Available for all seven geometric types, for all combinations
11141 of <type>point</type> with another geometric type, and for
11142 these additional pairs of types:
11143 (<type>box</type>, <type>lseg</type>),
11144 (<type>lseg</type>, <type>line</type>),
11145 (<type>polygon</type>, <type>circle</type>)
11146 (and the commutator cases).
11147 </para>
11148 <para>
11149 <literal>circle '&lt;(0,0),1&gt;' &lt;-&gt; circle '&lt;(5,0),1&gt;'</literal>
11150 <returnvalue>3</returnvalue>
11151 </para></entry>
11152 </row>
11154 <row>
11155 <entry role="func_table_entry"><para role="func_signature">
11156 <replaceable>geometric_type</replaceable> <literal>@&gt;</literal> <replaceable>geometric_type</replaceable>
11157 <returnvalue>boolean</returnvalue>
11158 </para>
11159 <para>
11160 Does first object contain second?
11161 Available for these pairs of types:
11162 (<literal>box</literal>, <literal>point</literal>),
11163 (<literal>box</literal>, <literal>box</literal>),
11164 (<literal>path</literal>, <literal>point</literal>),
11165 (<literal>polygon</literal>, <literal>point</literal>),
11166 (<literal>polygon</literal>, <literal>polygon</literal>),
11167 (<literal>circle</literal>, <literal>point</literal>),
11168 (<literal>circle</literal>, <literal>circle</literal>).
11169 </para>
11170 <para>
11171 <literal>circle '&lt;(0,0),2&gt;' @&gt; point '(1,1)'</literal>
11172 <returnvalue>t</returnvalue>
11173 </para></entry>
11174 </row>
11176 <row>
11177 <entry role="func_table_entry"><para role="func_signature">
11178 <replaceable>geometric_type</replaceable> <literal>&lt;@</literal> <replaceable>geometric_type</replaceable>
11179 <returnvalue>boolean</returnvalue>
11180 </para>
11181 <para>
11182 Is first object contained in or on second?
11183 Available for these pairs of types:
11184 (<literal>point</literal>, <literal>box</literal>),
11185 (<literal>point</literal>, <literal>lseg</literal>),
11186 (<literal>point</literal>, <literal>line</literal>),
11187 (<literal>point</literal>, <literal>path</literal>),
11188 (<literal>point</literal>, <literal>polygon</literal>),
11189 (<literal>point</literal>, <literal>circle</literal>),
11190 (<literal>box</literal>, <literal>box</literal>),
11191 (<literal>lseg</literal>, <literal>box</literal>),
11192 (<literal>lseg</literal>, <literal>line</literal>),
11193 (<literal>polygon</literal>, <literal>polygon</literal>),
11194 (<literal>circle</literal>, <literal>circle</literal>).
11195 </para>
11196 <para>
11197 <literal>point '(1,1)' &lt;@ circle '&lt;(0,0),2&gt;'</literal>
11198 <returnvalue>t</returnvalue>
11199 </para></entry>
11200 </row>
11202 <row>
11203 <entry role="func_table_entry"><para role="func_signature">
11204 <replaceable>geometric_type</replaceable> <literal>&amp;&amp;</literal> <replaceable>geometric_type</replaceable>
11205 <returnvalue>boolean</returnvalue>
11206 </para>
11207 <para>
11208 Do these objects overlap? (One point in common makes this true.)
11209 Available for <type>box</type>, <type>polygon</type>,
11210 <type>circle</type>.
11211 </para>
11212 <para>
11213 <literal>box '(1,1),(0,0)' &amp;&amp; box '(2,2),(0,0)'</literal>
11214 <returnvalue>t</returnvalue>
11215 </para></entry>
11216 </row>
11218 <row>
11219 <entry role="func_table_entry"><para role="func_signature">
11220 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;</literal> <replaceable>geometric_type</replaceable>
11221 <returnvalue>boolean</returnvalue>
11222 </para>
11223 <para>
11224 Is first object strictly left of second?
11225 Available for <type>point</type>, <type>box</type>,
11226 <type>polygon</type>, <type>circle</type>.
11227 </para>
11228 <para>
11229 <literal>circle '&lt;(0,0),1&gt;' &lt;&lt; circle '&lt;(5,0),1&gt;'</literal>
11230 <returnvalue>t</returnvalue>
11231 </para></entry>
11232 </row>
11234 <row>
11235 <entry role="func_table_entry"><para role="func_signature">
11236 <replaceable>geometric_type</replaceable> <literal>&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11237 <returnvalue>boolean</returnvalue>
11238 </para>
11239 <para>
11240 Is first object strictly right of second?
11241 Available for <type>point</type>, <type>box</type>,
11242 <type>polygon</type>, <type>circle</type>.
11243 </para>
11244 <para>
11245 <literal>circle '&lt;(5,0),1&gt;' &gt;&gt; circle '&lt;(0,0),1&gt;'</literal>
11246 <returnvalue>t</returnvalue>
11247 </para></entry>
11248 </row>
11250 <row>
11251 <entry role="func_table_entry"><para role="func_signature">
11252 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;</literal> <replaceable>geometric_type</replaceable>
11253 <returnvalue>boolean</returnvalue>
11254 </para>
11255 <para>
11256 Does first object not extend to the right of second?
11257 Available for <type>box</type>, <type>polygon</type>,
11258 <type>circle</type>.
11259 </para>
11260 <para>
11261 <literal>box '(1,1),(0,0)' &amp;&lt; box '(2,2),(0,0)'</literal>
11262 <returnvalue>t</returnvalue>
11263 </para></entry>
11264 </row>
11266 <row>
11267 <entry role="func_table_entry"><para role="func_signature">
11268 <replaceable>geometric_type</replaceable> <literal>&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11269 <returnvalue>boolean</returnvalue>
11270 </para>
11271 <para>
11272 Does first object not extend to the left of second?
11273 Available for <type>box</type>, <type>polygon</type>,
11274 <type>circle</type>.
11275 </para>
11276 <para>
11277 <literal>box '(3,3),(0,0)' &amp;&gt; box '(2,2),(0,0)'</literal>
11278 <returnvalue>t</returnvalue>
11279 </para></entry>
11280 </row>
11282 <row>
11283 <entry role="func_table_entry"><para role="func_signature">
11284 <replaceable>geometric_type</replaceable> <literal>&lt;&lt;|</literal> <replaceable>geometric_type</replaceable>
11285 <returnvalue>boolean</returnvalue>
11286 </para>
11287 <para>
11288 Is first object strictly below second?
11289 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11290 <type>circle</type>.
11291 </para>
11292 <para>
11293 <literal>box '(3,3),(0,0)' &lt;&lt;| box '(5,5),(3,4)'</literal>
11294 <returnvalue>t</returnvalue>
11295 </para></entry>
11296 </row>
11298 <row>
11299 <entry role="func_table_entry"><para role="func_signature">
11300 <replaceable>geometric_type</replaceable> <literal>|&gt;&gt;</literal> <replaceable>geometric_type</replaceable>
11301 <returnvalue>boolean</returnvalue>
11302 </para>
11303 <para>
11304 Is first object strictly above second?
11305 Available for <type>point</type>, <type>box</type>, <type>polygon</type>,
11306 <type>circle</type>.
11307 </para>
11308 <para>
11309 <literal>box '(5,5),(3,4)' |&gt;&gt; box '(3,3),(0,0)'</literal>
11310 <returnvalue>t</returnvalue>
11311 </para></entry>
11312 </row>
11314 <row>
11315 <entry role="func_table_entry"><para role="func_signature">
11316 <replaceable>geometric_type</replaceable> <literal>&amp;&lt;|</literal> <replaceable>geometric_type</replaceable>
11317 <returnvalue>boolean</returnvalue>
11318 </para>
11319 <para>
11320 Does first object not extend above second?
11321 Available for <type>box</type>, <type>polygon</type>,
11322 <type>circle</type>.
11323 </para>
11324 <para>
11325 <literal>box '(1,1),(0,0)' &amp;&lt;| box '(2,2),(0,0)'</literal>
11326 <returnvalue>t</returnvalue>
11327 </para></entry>
11328 </row>
11330 <row>
11331 <entry role="func_table_entry"><para role="func_signature">
11332 <replaceable>geometric_type</replaceable> <literal>|&amp;&gt;</literal> <replaceable>geometric_type</replaceable>
11333 <returnvalue>boolean</returnvalue>
11334 </para>
11335 <para>
11336 Does first object not extend below second?
11337 Available for <type>box</type>, <type>polygon</type>,
11338 <type>circle</type>.
11339 </para>
11340 <para>
11341 <literal>box '(3,3),(0,0)' |&amp;&gt; box '(2,2),(0,0)'</literal>
11342 <returnvalue>t</returnvalue>
11343 </para></entry>
11344 </row>
11346 <row>
11347 <entry role="func_table_entry"><para role="func_signature">
11348 <type>box</type> <literal>&lt;^</literal> <type>box</type>
11349 <returnvalue>boolean</returnvalue>
11350 </para>
11351 <para>
11352 Is first object below second (allows edges to touch)?
11353 </para>
11354 <para>
11355 <literal>box '((1,1),(0,0))' &lt;^ box '((2,2),(1,1))'</literal>
11356 <returnvalue>t</returnvalue>
11357 </para></entry>
11358 </row>
11360 <row>
11361 <entry role="func_table_entry"><para role="func_signature">
11362 <type>box</type> <literal>&gt;^</literal> <type>box</type>
11363 <returnvalue>boolean</returnvalue>
11364 </para>
11365 <para>
11366 Is first object above second (allows edges to touch)?
11367 </para>
11368 <para>
11369 <literal>box '((2,2),(1,1))' &gt;^ box '((1,1),(0,0))'</literal>
11370 <returnvalue>t</returnvalue>
11371 </para></entry>
11372 </row>
11374 <row>
11375 <entry role="func_table_entry"><para role="func_signature">
11376 <replaceable>geometric_type</replaceable> <literal>?#</literal> <replaceable>geometric_type</replaceable>
11377 <returnvalue>boolean</returnvalue>
11378 </para>
11379 <para>
11380 Do these objects intersect?
11381 Available for these pairs of types:
11382 (<type>box</type>, <type>box</type>),
11383 (<type>lseg</type>, <type>box</type>),
11384 (<type>lseg</type>, <type>lseg</type>),
11385 (<type>lseg</type>, <type>line</type>),
11386 (<type>line</type>, <type>box</type>),
11387 (<type>line</type>, <type>line</type>),
11388 (<type>path</type>, <type>path</type>).
11389 </para>
11390 <para>
11391 <literal>lseg '[(-1,0),(1,0)]' ?# box '(2,2),(-2,-2)'</literal>
11392 <returnvalue>t</returnvalue>
11393 </para></entry>
11394 </row>
11396 <row>
11397 <entry role="func_table_entry"><para role="func_signature">
11398 <literal>?-</literal> <type>line</type>
11399 <returnvalue>boolean</returnvalue>
11400 </para>
11401 <para role="func_signature">
11402 <literal>?-</literal> <type>lseg</type>
11403 <returnvalue>boolean</returnvalue>
11404 </para>
11405 <para>
11406 Is line horizontal?
11407 </para>
11408 <para>
11409 <literal>?- lseg '[(-1,0),(1,0)]'</literal>
11410 <returnvalue>t</returnvalue>
11411 </para></entry>
11412 </row>
11414 <row>
11415 <entry role="func_table_entry"><para role="func_signature">
11416 <type>point</type> <literal>?-</literal> <type>point</type>
11417 <returnvalue>boolean</returnvalue>
11418 </para>
11419 <para>
11420 Are points horizontally aligned (that is, have same y coordinate)?
11421 </para>
11422 <para>
11423 <literal>point '(1,0)' ?- point '(0,0)'</literal>
11424 <returnvalue>t</returnvalue>
11425 </para></entry>
11426 </row>
11428 <row>
11429 <entry role="func_table_entry"><para role="func_signature">
11430 <literal>?|</literal> <type>line</type>
11431 <returnvalue>boolean</returnvalue>
11432 </para>
11433 <para role="func_signature">
11434 <literal>?|</literal> <type>lseg</type>
11435 <returnvalue>boolean</returnvalue>
11436 </para>
11437 <para>
11438 Is line vertical?
11439 </para>
11440 <para>
11441 <literal>?| lseg '[(-1,0),(1,0)]'</literal>
11442 <returnvalue>f</returnvalue>
11443 </para></entry>
11444 </row>
11446 <row>
11447 <entry role="func_table_entry"><para role="func_signature">
11448 <type>point</type> <literal>?|</literal> <type>point</type>
11449 <returnvalue>boolean</returnvalue>
11450 </para>
11451 <para>
11452 Are points vertically aligned (that is, have same x coordinate)?
11453 </para>
11454 <para>
11455 <literal>point '(0,1)' ?| point '(0,0)'</literal>
11456 <returnvalue>t</returnvalue>
11457 </para></entry>
11458 </row>
11460 <row>
11461 <entry role="func_table_entry"><para role="func_signature">
11462 <type>line</type> <literal>?-|</literal> <type>line</type>
11463 <returnvalue>boolean</returnvalue>
11464 </para>
11465 <para role="func_signature">
11466 <type>lseg</type> <literal>?-|</literal> <type>lseg</type>
11467 <returnvalue>boolean</returnvalue>
11468 </para>
11469 <para>
11470 Are lines perpendicular?
11471 </para>
11472 <para>
11473 <literal>lseg '[(0,0),(0,1)]' ?-| lseg '[(0,0),(1,0)]'</literal>
11474 <returnvalue>t</returnvalue>
11475 </para></entry>
11476 </row>
11478 <row>
11479 <entry role="func_table_entry"><para role="func_signature">
11480 <type>line</type> <literal>?||</literal> <type>line</type>
11481 <returnvalue>boolean</returnvalue>
11482 </para>
11483 <para role="func_signature">
11484 <type>lseg</type> <literal>?||</literal> <type>lseg</type>
11485 <returnvalue>boolean</returnvalue>
11486 </para>
11487 <para>
11488 Are lines parallel?
11489 </para>
11490 <para>
11491 <literal>lseg '[(-1,0),(1,0)]' ?|| lseg '[(-1,2),(1,2)]'</literal>
11492 <returnvalue>t</returnvalue>
11493 </para></entry>
11494 </row>
11496 <row>
11497 <entry role="func_table_entry"><para role="func_signature">
11498 <replaceable>geometric_type</replaceable> <literal>~=</literal> <replaceable>geometric_type</replaceable>
11499 <returnvalue>boolean</returnvalue>
11500 </para>
11501 <para>
11502 Are these objects the same?
11503 Available for <type>point</type>, <type>box</type>,
11504 <type>polygon</type>, <type>circle</type>.
11505 </para>
11506 <para>
11507 <literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal>
11508 <returnvalue>t</returnvalue>
11509 </para></entry>
11510 </row>
11511 </tbody>
11512 </tgroup>
11513 </table>
11515 <caution>
11516 <para>
11517 Note that the <quote>same as</quote> operator, <literal>~=</literal>,
11518 represents the usual notion of equality for the <type>point</type>,
11519 <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
11520 Some of the geometric types also have an <literal>=</literal> operator, but
11521 <literal>=</literal> compares for equal <emphasis>areas</emphasis> only.
11522 The other scalar comparison operators (<literal>&lt;=</literal> and so
11523 on), where available for these types, likewise compare areas.
11524 </para>
11525 </caution>
11527 <note>
11528 <para>
11529 Before <productname>PostgreSQL</productname> 14, the point
11530 is strictly below/above comparison operators <type>point</type>
11531 <literal>&lt;&lt;|</literal> <type>point</type> and <type>point</type>
11532 <literal>|&gt;&gt;</literal> <type>point</type> were respectively
11533 called <literal>&lt;^</literal> and <literal>&gt;^</literal>. These
11534 names are still available, but are deprecated and will eventually be
11535 removed.
11536 </para>
11537 </note>
11539 <table id="functions-geometry-func-table">
11540 <title>Geometric Functions</title>
11541 <tgroup cols="1">
11542 <thead>
11543 <row>
11544 <entry role="func_table_entry"><para role="func_signature">
11545 Function
11546 </para>
11547 <para>
11548 Description
11549 </para>
11550 <para>
11551 Example(s)
11552 </para></entry>
11553 </row>
11554 </thead>
11556 <tbody>
11557 <row>
11558 <entry role="func_table_entry"><para role="func_signature">
11559 <indexterm>
11560 <primary>area</primary>
11561 </indexterm>
11562 <function>area</function> ( <replaceable>geometric_type</replaceable> )
11563 <returnvalue>double precision</returnvalue>
11564 </para>
11565 <para>
11566 Computes area.
11567 Available for <type>box</type>, <type>path</type>, <type>circle</type>.
11568 A <type>path</type> input must be closed, else NULL is returned.
11569 Also, if the <type>path</type> is self-intersecting, the result may be
11570 meaningless.
11571 </para>
11572 <para>
11573 <literal>area(box '(2,2),(0,0)')</literal>
11574 <returnvalue>4</returnvalue>
11575 </para></entry>
11576 </row>
11578 <row>
11579 <entry role="func_table_entry"><para role="func_signature">
11580 <indexterm>
11581 <primary>center</primary>
11582 </indexterm>
11583 <function>center</function> ( <replaceable>geometric_type</replaceable> )
11584 <returnvalue>point</returnvalue>
11585 </para>
11586 <para>
11587 Computes center point.
11588 Available for <type>box</type>, <type>circle</type>.
11589 </para>
11590 <para>
11591 <literal>center(box '(1,2),(0,0)')</literal>
11592 <returnvalue>(0.5,1)</returnvalue>
11593 </para></entry>
11594 </row>
11596 <row>
11597 <entry role="func_table_entry"><para role="func_signature">
11598 <indexterm>
11599 <primary>diagonal</primary>
11600 </indexterm>
11601 <function>diagonal</function> ( <type>box</type> )
11602 <returnvalue>lseg</returnvalue>
11603 </para>
11604 <para>
11605 Extracts box's diagonal as a line segment
11606 (same as <function>lseg(box)</function>).
11607 </para>
11608 <para>
11609 <literal>diagonal(box '(1,2),(0,0)')</literal>
11610 <returnvalue>[(1,2),(0,0)]</returnvalue>
11611 </para></entry>
11612 </row>
11614 <row>
11615 <entry role="func_table_entry"><para role="func_signature">
11616 <indexterm>
11617 <primary>diameter</primary>
11618 </indexterm>
11619 <function>diameter</function> ( <type>circle</type> )
11620 <returnvalue>double precision</returnvalue>
11621 </para>
11622 <para>
11623 Computes diameter of circle.
11624 </para>
11625 <para>
11626 <literal>diameter(circle '&lt;(0,0),2&gt;')</literal>
11627 <returnvalue>4</returnvalue>
11628 </para></entry>
11629 </row>
11631 <row>
11632 <entry role="func_table_entry"><para role="func_signature">
11633 <indexterm>
11634 <primary>height</primary>
11635 </indexterm>
11636 <function>height</function> ( <type>box</type> )
11637 <returnvalue>double precision</returnvalue>
11638 </para>
11639 <para>
11640 Computes vertical size of box.
11641 </para>
11642 <para>
11643 <literal>height(box '(1,2),(0,0)')</literal>
11644 <returnvalue>2</returnvalue>
11645 </para></entry>
11646 </row>
11648 <row>
11649 <entry role="func_table_entry"><para role="func_signature">
11650 <indexterm>
11651 <primary>isclosed</primary>
11652 </indexterm>
11653 <function>isclosed</function> ( <type>path</type> )
11654 <returnvalue>boolean</returnvalue>
11655 </para>
11656 <para>
11657 Is path closed?
11658 </para>
11659 <para>
11660 <literal>isclosed(path '((0,0),(1,1),(2,0))')</literal>
11661 <returnvalue>t</returnvalue>
11662 </para></entry>
11663 </row>
11665 <row>
11666 <entry role="func_table_entry"><para role="func_signature">
11667 <indexterm>
11668 <primary>isopen</primary>
11669 </indexterm>
11670 <function>isopen</function> ( <type>path</type> )
11671 <returnvalue>boolean</returnvalue>
11672 </para>
11673 <para>
11674 Is path open?
11675 </para>
11676 <para>
11677 <literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal>
11678 <returnvalue>t</returnvalue>
11679 </para></entry>
11680 </row>
11682 <row>
11683 <entry role="func_table_entry"><para role="func_signature">
11684 <indexterm>
11685 <primary>length</primary>
11686 </indexterm>
11687 <function>length</function> ( <replaceable>geometric_type</replaceable> )
11688 <returnvalue>double precision</returnvalue>
11689 </para>
11690 <para>
11691 Computes the total length.
11692 Available for <type>lseg</type>, <type>path</type>.
11693 </para>
11694 <para>
11695 <literal>length(path '((-1,0),(1,0))')</literal>
11696 <returnvalue>4</returnvalue>
11697 </para></entry>
11698 </row>
11700 <row>
11701 <entry role="func_table_entry"><para role="func_signature">
11702 <indexterm>
11703 <primary>npoints</primary>
11704 </indexterm>
11705 <function>npoints</function> ( <replaceable>geometric_type</replaceable> )
11706 <returnvalue>integer</returnvalue>
11707 </para>
11708 <para>
11709 Returns the number of points.
11710 Available for <type>path</type>, <type>polygon</type>.
11711 </para>
11712 <para>
11713 <literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal>
11714 <returnvalue>3</returnvalue>
11715 </para></entry>
11716 </row>
11718 <row>
11719 <entry role="func_table_entry"><para role="func_signature">
11720 <indexterm>
11721 <primary>pclose</primary>
11722 </indexterm>
11723 <function>pclose</function> ( <type>path</type> )
11724 <returnvalue>path</returnvalue>
11725 </para>
11726 <para>
11727 Converts path to closed form.
11728 </para>
11729 <para>
11730 <literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal>
11731 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
11732 </para></entry>
11733 </row>
11735 <row>
11736 <entry role="func_table_entry"><para role="func_signature">
11737 <indexterm>
11738 <primary>popen</primary>
11739 </indexterm>
11740 <function>popen</function> ( <type>path</type> )
11741 <returnvalue>path</returnvalue>
11742 </para>
11743 <para>
11744 Converts path to open form.
11745 </para>
11746 <para>
11747 <literal>popen(path '((0,0),(1,1),(2,0))')</literal>
11748 <returnvalue>[(0,0),(1,1),(2,0)]</returnvalue>
11749 </para></entry>
11750 </row>
11752 <row>
11753 <entry role="func_table_entry"><para role="func_signature">
11754 <indexterm>
11755 <primary>radius</primary>
11756 </indexterm>
11757 <function>radius</function> ( <type>circle</type> )
11758 <returnvalue>double precision</returnvalue>
11759 </para>
11760 <para>
11761 Computes radius of circle.
11762 </para>
11763 <para>
11764 <literal>radius(circle '&lt;(0,0),2&gt;')</literal>
11765 <returnvalue>2</returnvalue>
11766 </para></entry>
11767 </row>
11769 <row>
11770 <entry role="func_table_entry"><para role="func_signature">
11771 <indexterm>
11772 <primary>slope</primary>
11773 </indexterm>
11774 <function>slope</function> ( <type>point</type>, <type>point</type> )
11775 <returnvalue>double precision</returnvalue>
11776 </para>
11777 <para>
11778 Computes slope of a line drawn through the two points.
11779 </para>
11780 <para>
11781 <literal>slope(point '(0,0)', point '(2,1)')</literal>
11782 <returnvalue>0.5</returnvalue>
11783 </para></entry>
11784 </row>
11786 <row>
11787 <entry role="func_table_entry"><para role="func_signature">
11788 <indexterm>
11789 <primary>width</primary>
11790 </indexterm>
11791 <function>width</function> ( <type>box</type> )
11792 <returnvalue>double precision</returnvalue>
11793 </para>
11794 <para>
11795 Computes horizontal size of box.
11796 </para>
11797 <para>
11798 <literal>width(box '(1,2),(0,0)')</literal>
11799 <returnvalue>1</returnvalue>
11800 </para></entry>
11801 </row>
11802 </tbody>
11803 </tgroup>
11804 </table>
11806 <table id="functions-geometry-conv-table">
11807 <title>Geometric Type Conversion Functions</title>
11808 <tgroup cols="1">
11809 <thead>
11810 <row>
11811 <entry role="func_table_entry"><para role="func_signature">
11812 Function
11813 </para>
11814 <para>
11815 Description
11816 </para>
11817 <para>
11818 Example(s)
11819 </para></entry>
11820 </row>
11821 </thead>
11822 <tbody>
11824 <row>
11825 <entry role="func_table_entry"><para role="func_signature">
11826 <indexterm>
11827 <primary>box</primary>
11828 </indexterm>
11829 <function>box</function> ( <type>circle</type> )
11830 <returnvalue>box</returnvalue>
11831 </para>
11832 <para>
11833 Computes box inscribed within the circle.
11834 </para>
11835 <para>
11836 <literal>box(circle '&lt;(0,0),2&gt;')</literal>
11837 <returnvalue>(1.414213562373095,1.414213562373095),&zwsp;(-1.414213562373095,-1.414213562373095)</returnvalue>
11838 </para></entry>
11839 </row>
11841 <row>
11842 <entry role="func_table_entry"><para role="func_signature">
11843 <function>box</function> ( <type>point</type> )
11844 <returnvalue>box</returnvalue>
11845 </para>
11846 <para>
11847 Converts point to empty box.
11848 </para>
11849 <para>
11850 <literal>box(point '(1,0)')</literal>
11851 <returnvalue>(1,0),(1,0)</returnvalue>
11852 </para></entry>
11853 </row>
11855 <row>
11856 <entry role="func_table_entry"><para role="func_signature">
11857 <function>box</function> ( <type>point</type>, <type>point</type> )
11858 <returnvalue>box</returnvalue>
11859 </para>
11860 <para>
11861 Converts any two corner points to box.
11862 </para>
11863 <para>
11864 <literal>box(point '(0,1)', point '(1,0)')</literal>
11865 <returnvalue>(1,1),(0,0)</returnvalue>
11866 </para></entry>
11867 </row>
11869 <row>
11870 <entry role="func_table_entry"><para role="func_signature">
11871 <function>box</function> ( <type>polygon</type> )
11872 <returnvalue>box</returnvalue>
11873 </para>
11874 <para>
11875 Computes bounding box of polygon.
11876 </para>
11877 <para>
11878 <literal>box(polygon '((0,0),(1,1),(2,0))')</literal>
11879 <returnvalue>(2,1),(0,0)</returnvalue>
11880 </para></entry>
11881 </row>
11883 <row>
11884 <entry role="func_table_entry"><para role="func_signature">
11885 <indexterm>
11886 <primary>bound_box</primary>
11887 </indexterm>
11888 <function>bound_box</function> ( <type>box</type>, <type>box</type> )
11889 <returnvalue>box</returnvalue>
11890 </para>
11891 <para>
11892 Computes bounding box of two boxes.
11893 </para>
11894 <para>
11895 <literal>bound_box(box '(1,1),(0,0)', box '(4,4),(3,3)')</literal>
11896 <returnvalue>(4,4),(0,0)</returnvalue>
11897 </para></entry>
11898 </row>
11900 <row>
11901 <entry role="func_table_entry"><para role="func_signature">
11902 <indexterm>
11903 <primary>circle</primary>
11904 </indexterm>
11905 <function>circle</function> ( <type>box</type> )
11906 <returnvalue>circle</returnvalue>
11907 </para>
11908 <para>
11909 Computes smallest circle enclosing box.
11910 </para>
11911 <para>
11912 <literal>circle(box '(1,1),(0,0)')</literal>
11913 <returnvalue>&lt;(0.5,0.5),0.7071067811865476&gt;</returnvalue>
11914 </para></entry>
11915 </row>
11917 <row>
11918 <entry role="func_table_entry"><para role="func_signature">
11919 <function>circle</function> ( <type>point</type>, <type>double precision</type> )
11920 <returnvalue>circle</returnvalue>
11921 </para>
11922 <para>
11923 Constructs circle from center and radius.
11924 </para>
11925 <para>
11926 <literal>circle(point '(0,0)', 2.0)</literal>
11927 <returnvalue>&lt;(0,0),2&gt;</returnvalue>
11928 </para></entry>
11929 </row>
11931 <row>
11932 <entry role="func_table_entry"><para role="func_signature">
11933 <function>circle</function> ( <type>polygon</type> )
11934 <returnvalue>circle</returnvalue>
11935 </para>
11936 <para>
11937 Converts polygon to circle. The circle's center is the mean of the
11938 positions of the polygon's points, and the radius is the average
11939 distance of the polygon's points from that center.
11940 </para>
11941 <para>
11942 <literal>circle(polygon '((0,0),(1,3),(2,0))')</literal>
11943 <returnvalue>&lt;(1,1),1.6094757082487299&gt;</returnvalue>
11944 </para></entry>
11945 </row>
11947 <row>
11948 <entry role="func_table_entry"><para role="func_signature">
11949 <indexterm>
11950 <primary>line</primary>
11951 </indexterm>
11952 <function>line</function> ( <type>point</type>, <type>point</type> )
11953 <returnvalue>line</returnvalue>
11954 </para>
11955 <para>
11956 Converts two points to the line through them.
11957 </para>
11958 <para>
11959 <literal>line(point '(-1,0)', point '(1,0)')</literal>
11960 <returnvalue>{0,-1,0}</returnvalue>
11961 </para></entry>
11962 </row>
11964 <row>
11965 <entry role="func_table_entry"><para role="func_signature">
11966 <indexterm>
11967 <primary>lseg</primary>
11968 </indexterm>
11969 <function>lseg</function> ( <type>box</type> )
11970 <returnvalue>lseg</returnvalue>
11971 </para>
11972 <para>
11973 Extracts box's diagonal as a line segment.
11974 </para>
11975 <para>
11976 <literal>lseg(box '(1,0),(-1,0)')</literal>
11977 <returnvalue>[(1,0),(-1,0)]</returnvalue>
11978 </para></entry>
11979 </row>
11981 <row>
11982 <entry role="func_table_entry"><para role="func_signature">
11983 <function>lseg</function> ( <type>point</type>, <type>point</type> )
11984 <returnvalue>lseg</returnvalue>
11985 </para>
11986 <para>
11987 Constructs line segment from two endpoints.
11988 </para>
11989 <para>
11990 <literal>lseg(point '(-1,0)', point '(1,0)')</literal>
11991 <returnvalue>[(-1,0),(1,0)]</returnvalue>
11992 </para></entry>
11993 </row>
11995 <row>
11996 <entry role="func_table_entry"><para role="func_signature">
11997 <indexterm>
11998 <primary>path</primary>
11999 </indexterm>
12000 <function>path</function> ( <type>polygon</type> )
12001 <returnvalue>path</returnvalue>
12002 </para>
12003 <para>
12004 Converts polygon to a closed path with the same list of points.
12005 </para>
12006 <para>
12007 <literal>path(polygon '((0,0),(1,1),(2,0))')</literal>
12008 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12009 </para></entry>
12010 </row>
12012 <row>
12013 <entry role="func_table_entry"><para role="func_signature">
12014 <indexterm>
12015 <primary>point</primary>
12016 </indexterm>
12017 <function>point</function> ( <type>double precision</type>, <type>double precision</type> )
12018 <returnvalue>point</returnvalue>
12019 </para>
12020 <para>
12021 Constructs point from its coordinates.
12022 </para>
12023 <para>
12024 <literal>point(23.4, -44.5)</literal>
12025 <returnvalue>(23.4,-44.5)</returnvalue>
12026 </para></entry>
12027 </row>
12029 <row>
12030 <entry role="func_table_entry"><para role="func_signature">
12031 <function>point</function> ( <type>box</type> )
12032 <returnvalue>point</returnvalue>
12033 </para>
12034 <para>
12035 Computes center of box.
12036 </para>
12037 <para>
12038 <literal>point(box '(1,0),(-1,0)')</literal>
12039 <returnvalue>(0,0)</returnvalue>
12040 </para></entry>
12041 </row>
12043 <row>
12044 <entry role="func_table_entry"><para role="func_signature">
12045 <function>point</function> ( <type>circle</type> )
12046 <returnvalue>point</returnvalue>
12047 </para>
12048 <para>
12049 Computes center of circle.
12050 </para>
12051 <para>
12052 <literal>point(circle '&lt;(0,0),2&gt;')</literal>
12053 <returnvalue>(0,0)</returnvalue>
12054 </para></entry>
12055 </row>
12057 <row>
12058 <entry role="func_table_entry"><para role="func_signature">
12059 <function>point</function> ( <type>lseg</type> )
12060 <returnvalue>point</returnvalue>
12061 </para>
12062 <para>
12063 Computes center of line segment.
12064 </para>
12065 <para>
12066 <literal>point(lseg '[(-1,0),(1,0)]')</literal>
12067 <returnvalue>(0,0)</returnvalue>
12068 </para></entry>
12069 </row>
12071 <row>
12072 <entry role="func_table_entry"><para role="func_signature">
12073 <function>point</function> ( <type>polygon</type> )
12074 <returnvalue>point</returnvalue>
12075 </para>
12076 <para>
12077 Computes center of polygon (the mean of the
12078 positions of the polygon's points).
12079 </para>
12080 <para>
12081 <literal>point(polygon '((0,0),(1,1),(2,0))')</literal>
12082 <returnvalue>(1,0.3333333333333333)</returnvalue>
12083 </para></entry>
12084 </row>
12086 <row>
12087 <entry role="func_table_entry"><para role="func_signature">
12088 <indexterm>
12089 <primary>polygon</primary>
12090 </indexterm>
12091 <function>polygon</function> ( <type>box</type> )
12092 <returnvalue>polygon</returnvalue>
12093 </para>
12094 <para>
12095 Converts box to a 4-point polygon.
12096 </para>
12097 <para>
12098 <literal>polygon(box '(1,1),(0,0)')</literal>
12099 <returnvalue>((0,0),(0,1),(1,1),(1,0))</returnvalue>
12100 </para></entry>
12101 </row>
12103 <row>
12104 <entry role="func_table_entry"><para role="func_signature">
12105 <function>polygon</function> ( <type>circle</type> )
12106 <returnvalue>polygon</returnvalue>
12107 </para>
12108 <para>
12109 Converts circle to a 12-point polygon.
12110 </para>
12111 <para>
12112 <literal>polygon(circle '&lt;(0,0),2&gt;')</literal>
12113 <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>
12114 </para></entry>
12115 </row>
12117 <row>
12118 <entry role="func_table_entry"><para role="func_signature">
12119 <function>polygon</function> ( <type>integer</type>, <type>circle</type> )
12120 <returnvalue>polygon</returnvalue>
12121 </para>
12122 <para>
12123 Converts circle to an <replaceable>n</replaceable>-point polygon.
12124 </para>
12125 <para>
12126 <literal>polygon(4, circle '&lt;(3,0),1&gt;')</literal>
12127 <returnvalue>((2,0),&zwsp;(3,1),&zwsp;(4,1.2246063538223773e-16),&zwsp;(3,-1))</returnvalue>
12128 </para></entry>
12129 </row>
12131 <row>
12132 <entry role="func_table_entry"><para role="func_signature">
12133 <function>polygon</function> ( <type>path</type> )
12134 <returnvalue>polygon</returnvalue>
12135 </para>
12136 <para>
12137 Converts closed path to a polygon with the same list of points.
12138 </para>
12139 <para>
12140 <literal>polygon(path '((0,0),(1,1),(2,0))')</literal>
12141 <returnvalue>((0,0),(1,1),(2,0))</returnvalue>
12142 </para></entry>
12143 </row>
12145 </tbody>
12146 </tgroup>
12147 </table>
12149 <para>
12150 It is possible to access the two component numbers of a <type>point</type>
12151 as though the point were an array with indexes 0 and 1. For example, if
12152 <literal>t.p</literal> is a <type>point</type> column then
12153 <literal>SELECT p[0] FROM t</literal> retrieves the X coordinate and
12154 <literal>UPDATE t SET p[1] = ...</literal> changes the Y coordinate.
12155 In the same way, a value of type <type>box</type> or <type>lseg</type> can be treated
12156 as an array of two <type>point</type> values.
12157 </para>
12159 </sect1>
12162 <sect1 id="functions-net">
12163 <title>Network Address Functions and Operators</title>
12165 <para>
12166 The IP network address types, <type>cidr</type> and <type>inet</type>,
12167 support the usual comparison operators shown in
12168 <xref linkend="functions-comparison-op-table"/>
12169 as well as the specialized operators and functions shown in
12170 <xref linkend="cidr-inet-operators-table"/> and
12171 <xref linkend="cidr-inet-functions-table"/>.
12172 </para>
12174 <para>
12175 Any <type>cidr</type> value can be cast to <type>inet</type> implicitly;
12176 therefore, the operators and functions shown below as operating on
12177 <type>inet</type> also work on <type>cidr</type> values. (Where there are
12178 separate functions for <type>inet</type> and <type>cidr</type>, it is
12179 because the behavior should be different for the two cases.)
12180 Also, it is permitted to cast an <type>inet</type> value
12181 to <type>cidr</type>. When this is done, any bits to the right of the
12182 netmask are silently zeroed to create a valid <type>cidr</type> value.
12183 </para>
12185 <table id="cidr-inet-operators-table">
12186 <title>IP Address Operators</title>
12187 <tgroup cols="1">
12188 <thead>
12189 <row>
12190 <entry role="func_table_entry"><para role="func_signature">
12191 Operator
12192 </para>
12193 <para>
12194 Description
12195 </para>
12196 <para>
12197 Example(s)
12198 </para></entry>
12199 </row>
12200 </thead>
12202 <tbody>
12203 <row>
12204 <entry role="func_table_entry"><para role="func_signature">
12205 <type>inet</type> <literal>&lt;&lt;</literal> <type>inet</type>
12206 <returnvalue>boolean</returnvalue>
12207 </para>
12208 <para>
12209 Is subnet strictly contained by subnet?
12210 This operator, and the next four, test for subnet inclusion. They
12211 consider only the network parts of the two addresses (ignoring any
12212 bits to the right of the netmasks) and determine whether one network
12213 is identical to or a subnet of the other.
12214 </para>
12215 <para>
12216 <literal>inet '192.168.1.5' &lt;&lt; inet '192.168.1/24'</literal>
12217 <returnvalue>t</returnvalue>
12218 </para>
12219 <para>
12220 <literal>inet '192.168.0.5' &lt;&lt; inet '192.168.1/24'</literal>
12221 <returnvalue>f</returnvalue>
12222 </para>
12223 <para>
12224 <literal>inet '192.168.1/24' &lt;&lt; inet '192.168.1/24'</literal>
12225 <returnvalue>f</returnvalue>
12226 </para></entry>
12227 </row>
12229 <row>
12230 <entry role="func_table_entry"><para role="func_signature">
12231 <type>inet</type> <literal>&lt;&lt;=</literal> <type>inet</type>
12232 <returnvalue>boolean</returnvalue>
12233 </para>
12234 <para>
12235 Is subnet contained by or equal to subnet?
12236 </para>
12237 <para>
12238 <literal>inet '192.168.1/24' &lt;&lt;= inet '192.168.1/24'</literal>
12239 <returnvalue>t</returnvalue>
12240 </para></entry>
12241 </row>
12243 <row>
12244 <entry role="func_table_entry"><para role="func_signature">
12245 <type>inet</type> <literal>&gt;&gt;</literal> <type>inet</type>
12246 <returnvalue>boolean</returnvalue>
12247 </para>
12248 <para>
12249 Does subnet strictly contain subnet?
12250 </para>
12251 <para>
12252 <literal>inet '192.168.1/24' &gt;&gt; inet '192.168.1.5'</literal>
12253 <returnvalue>t</returnvalue>
12254 </para></entry>
12255 </row>
12257 <row>
12258 <entry role="func_table_entry"><para role="func_signature">
12259 <type>inet</type> <literal>&gt;&gt;=</literal> <type>inet</type>
12260 <returnvalue>boolean</returnvalue>
12261 </para>
12262 <para>
12263 Does subnet contain or equal subnet?
12264 </para>
12265 <para>
12266 <literal>inet '192.168.1/24' &gt;&gt;= inet '192.168.1/24'</literal>
12267 <returnvalue>t</returnvalue>
12268 </para></entry>
12269 </row>
12271 <row>
12272 <entry role="func_table_entry"><para role="func_signature">
12273 <type>inet</type> <literal>&amp;&amp;</literal> <type>inet</type>
12274 <returnvalue>boolean</returnvalue>
12275 </para>
12276 <para>
12277 Does either subnet contain or equal the other?
12278 </para>
12279 <para>
12280 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.1.80/28'</literal>
12281 <returnvalue>t</returnvalue>
12282 </para>
12283 <para>
12284 <literal>inet '192.168.1/24' &amp;&amp; inet '192.168.2.0/28'</literal>
12285 <returnvalue>f</returnvalue>
12286 </para></entry>
12287 </row>
12289 <row>
12290 <entry role="func_table_entry"><para role="func_signature">
12291 <literal>~</literal> <type>inet</type>
12292 <returnvalue>inet</returnvalue>
12293 </para>
12294 <para>
12295 Computes bitwise NOT.
12296 </para>
12297 <para>
12298 <literal>~ inet '192.168.1.6'</literal>
12299 <returnvalue>63.87.254.249</returnvalue>
12300 </para></entry>
12301 </row>
12303 <row>
12304 <entry role="func_table_entry"><para role="func_signature">
12305 <type>inet</type> <literal>&amp;</literal> <type>inet</type>
12306 <returnvalue>inet</returnvalue>
12307 </para>
12308 <para>
12309 Computes bitwise AND.
12310 </para>
12311 <para>
12312 <literal>inet '192.168.1.6' &amp; inet '0.0.0.255'</literal>
12313 <returnvalue>0.0.0.6</returnvalue>
12314 </para></entry>
12315 </row>
12317 <row>
12318 <entry role="func_table_entry"><para role="func_signature">
12319 <type>inet</type> <literal>|</literal> <type>inet</type>
12320 <returnvalue>inet</returnvalue>
12321 </para>
12322 <para>
12323 Computes bitwise OR.
12324 </para>
12325 <para>
12326 <literal>inet '192.168.1.6' | inet '0.0.0.255'</literal>
12327 <returnvalue>192.168.1.255</returnvalue>
12328 </para></entry>
12329 </row>
12331 <row>
12332 <entry role="func_table_entry"><para role="func_signature">
12333 <type>inet</type> <literal>+</literal> <type>bigint</type>
12334 <returnvalue>inet</returnvalue>
12335 </para>
12336 <para>
12337 Adds an offset to an address.
12338 </para>
12339 <para>
12340 <literal>inet '192.168.1.6' + 25</literal>
12341 <returnvalue>192.168.1.31</returnvalue>
12342 </para></entry>
12343 </row>
12345 <row>
12346 <entry role="func_table_entry"><para role="func_signature">
12347 <type>bigint</type> <literal>+</literal> <type>inet</type>
12348 <returnvalue>inet</returnvalue>
12349 </para>
12350 <para>
12351 Adds an offset to an address.
12352 </para>
12353 <para>
12354 <literal>200 + inet '::ffff:fff0:1'</literal>
12355 <returnvalue>::ffff:255.240.0.201</returnvalue>
12356 </para></entry>
12357 </row>
12359 <row>
12360 <entry role="func_table_entry"><para role="func_signature">
12361 <type>inet</type> <literal>-</literal> <type>bigint</type>
12362 <returnvalue>inet</returnvalue>
12363 </para>
12364 <para>
12365 Subtracts an offset from an address.
12366 </para>
12367 <para>
12368 <literal>inet '192.168.1.43' - 36</literal>
12369 <returnvalue>192.168.1.7</returnvalue>
12370 </para></entry>
12371 </row>
12373 <row>
12374 <entry role="func_table_entry"><para role="func_signature">
12375 <type>inet</type> <literal>-</literal> <type>inet</type>
12376 <returnvalue>bigint</returnvalue>
12377 </para>
12378 <para>
12379 Computes the difference of two addresses.
12380 </para>
12381 <para>
12382 <literal>inet '192.168.1.43' - inet '192.168.1.19'</literal>
12383 <returnvalue>24</returnvalue>
12384 </para>
12385 <para>
12386 <literal>inet '::1' - inet '::ffff:1'</literal>
12387 <returnvalue>-4294901760</returnvalue>
12388 </para></entry>
12389 </row>
12390 </tbody>
12391 </tgroup>
12392 </table>
12394 <table id="cidr-inet-functions-table">
12395 <title>IP Address Functions</title>
12396 <tgroup cols="1">
12397 <thead>
12398 <row>
12399 <entry role="func_table_entry"><para role="func_signature">
12400 Function
12401 </para>
12402 <para>
12403 Description
12404 </para>
12405 <para>
12406 Example(s)
12407 </para></entry>
12408 </row>
12409 </thead>
12411 <tbody>
12412 <row>
12413 <entry role="func_table_entry"><para role="func_signature">
12414 <indexterm>
12415 <primary>abbrev</primary>
12416 </indexterm>
12417 <function>abbrev</function> ( <type>inet</type> )
12418 <returnvalue>text</returnvalue>
12419 </para>
12420 <para>
12421 Creates an abbreviated display format as text.
12422 (The result is the same as the <type>inet</type> output function
12423 produces; it is <quote>abbreviated</quote> only in comparison to the
12424 result of an explicit cast to <type>text</type>, which for historical
12425 reasons will never suppress the netmask part.)
12426 </para>
12427 <para>
12428 <literal>abbrev(inet '10.1.0.0/32')</literal>
12429 <returnvalue>10.1.0.0</returnvalue>
12430 </para></entry>
12431 </row>
12433 <row>
12434 <entry role="func_table_entry"><para role="func_signature">
12435 <function>abbrev</function> ( <type>cidr</type> )
12436 <returnvalue>text</returnvalue>
12437 </para>
12438 <para>
12439 Creates an abbreviated display format as text.
12440 (The abbreviation consists of dropping all-zero octets to the right
12441 of the netmask; more examples are in
12442 <xref linkend="datatype-net-cidr-table"/>.)
12443 </para>
12444 <para>
12445 <literal>abbrev(cidr '10.1.0.0/16')</literal>
12446 <returnvalue>10.1/16</returnvalue>
12447 </para></entry>
12448 </row>
12450 <row>
12451 <entry role="func_table_entry"><para role="func_signature">
12452 <indexterm>
12453 <primary>broadcast</primary>
12454 </indexterm>
12455 <function>broadcast</function> ( <type>inet</type> )
12456 <returnvalue>inet</returnvalue>
12457 </para>
12458 <para>
12459 Computes the broadcast address for the address's network.
12460 </para>
12461 <para>
12462 <literal>broadcast(inet '192.168.1.5/24')</literal>
12463 <returnvalue>192.168.1.255/24</returnvalue>
12464 </para></entry>
12465 </row>
12467 <row>
12468 <entry role="func_table_entry"><para role="func_signature">
12469 <indexterm>
12470 <primary>family</primary>
12471 </indexterm>
12472 <function>family</function> ( <type>inet</type> )
12473 <returnvalue>integer</returnvalue>
12474 </para>
12475 <para>
12476 Returns the address's family: <literal>4</literal> for IPv4,
12477 <literal>6</literal> for IPv6.
12478 </para>
12479 <para>
12480 <literal>family(inet '::1')</literal>
12481 <returnvalue>6</returnvalue>
12482 </para></entry>
12483 </row>
12485 <row>
12486 <entry role="func_table_entry"><para role="func_signature">
12487 <indexterm>
12488 <primary>host</primary>
12489 </indexterm>
12490 <function>host</function> ( <type>inet</type> )
12491 <returnvalue>text</returnvalue>
12492 </para>
12493 <para>
12494 Returns the IP address as text, ignoring the netmask.
12495 </para>
12496 <para>
12497 <literal>host(inet '192.168.1.0/24')</literal>
12498 <returnvalue>192.168.1.0</returnvalue>
12499 </para></entry>
12500 </row>
12502 <row>
12503 <entry role="func_table_entry"><para role="func_signature">
12504 <indexterm>
12505 <primary>hostmask</primary>
12506 </indexterm>
12507 <function>hostmask</function> ( <type>inet</type> )
12508 <returnvalue>inet</returnvalue>
12509 </para>
12510 <para>
12511 Computes the host mask for the address's network.
12512 </para>
12513 <para>
12514 <literal>hostmask(inet '192.168.23.20/30')</literal>
12515 <returnvalue>0.0.0.3</returnvalue>
12516 </para></entry>
12517 </row>
12519 <row>
12520 <entry role="func_table_entry"><para role="func_signature">
12521 <indexterm>
12522 <primary>inet_merge</primary>
12523 </indexterm>
12524 <function>inet_merge</function> ( <type>inet</type>, <type>inet</type> )
12525 <returnvalue>cidr</returnvalue>
12526 </para>
12527 <para>
12528 Computes the smallest network that includes both of the given networks.
12529 </para>
12530 <para>
12531 <literal>inet_merge(inet '192.168.1.5/24', inet '192.168.2.5/24')</literal>
12532 <returnvalue>192.168.0.0/22</returnvalue>
12533 </para></entry>
12534 </row>
12536 <row>
12537 <entry role="func_table_entry"><para role="func_signature">
12538 <indexterm>
12539 <primary>inet_same_family</primary>
12540 </indexterm>
12541 <function>inet_same_family</function> ( <type>inet</type>, <type>inet</type> )
12542 <returnvalue>boolean</returnvalue>
12543 </para>
12544 <para>
12545 Tests whether the addresses belong to the same IP family.
12546 </para>
12547 <para>
12548 <literal>inet_same_family(inet '192.168.1.5/24', inet '::1')</literal>
12549 <returnvalue>f</returnvalue>
12550 </para></entry>
12551 </row>
12553 <row>
12554 <entry role="func_table_entry"><para role="func_signature">
12555 <indexterm>
12556 <primary>masklen</primary>
12557 </indexterm>
12558 <function>masklen</function> ( <type>inet</type> )
12559 <returnvalue>integer</returnvalue>
12560 </para>
12561 <para>
12562 Returns the netmask length in bits.
12563 </para>
12564 <para>
12565 <literal>masklen(inet '192.168.1.5/24')</literal>
12566 <returnvalue>24</returnvalue>
12567 </para></entry>
12568 </row>
12570 <row>
12571 <entry role="func_table_entry"><para role="func_signature">
12572 <indexterm>
12573 <primary>netmask</primary>
12574 </indexterm>
12575 <function>netmask</function> ( <type>inet</type> )
12576 <returnvalue>inet</returnvalue>
12577 </para>
12578 <para>
12579 Computes the network mask for the address's network.
12580 </para>
12581 <para>
12582 <literal>netmask(inet '192.168.1.5/24')</literal>
12583 <returnvalue>255.255.255.0</returnvalue>
12584 </para></entry>
12585 </row>
12587 <row>
12588 <entry role="func_table_entry"><para role="func_signature">
12589 <indexterm>
12590 <primary>network</primary>
12591 </indexterm>
12592 <function>network</function> ( <type>inet</type> )
12593 <returnvalue>cidr</returnvalue>
12594 </para>
12595 <para>
12596 Returns the network part of the address, zeroing out
12597 whatever is to the right of the netmask.
12598 (This is equivalent to casting the value to <type>cidr</type>.)
12599 </para>
12600 <para>
12601 <literal>network(inet '192.168.1.5/24')</literal>
12602 <returnvalue>192.168.1.0/24</returnvalue>
12603 </para></entry>
12604 </row>
12606 <row>
12607 <entry role="func_table_entry"><para role="func_signature">
12608 <indexterm>
12609 <primary>set_masklen</primary>
12610 </indexterm>
12611 <function>set_masklen</function> ( <type>inet</type>, <type>integer</type> )
12612 <returnvalue>inet</returnvalue>
12613 </para>
12614 <para>
12615 Sets the netmask length for an <type>inet</type> value.
12616 The address part does not change.
12617 </para>
12618 <para>
12619 <literal>set_masklen(inet '192.168.1.5/24', 16)</literal>
12620 <returnvalue>192.168.1.5/16</returnvalue>
12621 </para></entry>
12622 </row>
12624 <row>
12625 <entry role="func_table_entry"><para role="func_signature">
12626 <function>set_masklen</function> ( <type>cidr</type>, <type>integer</type> )
12627 <returnvalue>cidr</returnvalue>
12628 </para>
12629 <para>
12630 Sets the netmask length for a <type>cidr</type> value.
12631 Address bits to the right of the new netmask are set to zero.
12632 </para>
12633 <para>
12634 <literal>set_masklen(cidr '192.168.1.0/24', 16)</literal>
12635 <returnvalue>192.168.0.0/16</returnvalue>
12636 </para></entry>
12637 </row>
12639 <row>
12640 <entry role="func_table_entry"><para role="func_signature">
12641 <indexterm>
12642 <primary>text</primary>
12643 </indexterm>
12644 <function>text</function> ( <type>inet</type> )
12645 <returnvalue>text</returnvalue>
12646 </para>
12647 <para>
12648 Returns the unabbreviated IP address and netmask length as text.
12649 (This has the same result as an explicit cast to <type>text</type>.)
12650 </para>
12651 <para>
12652 <literal>text(inet '192.168.1.5')</literal>
12653 <returnvalue>192.168.1.5/32</returnvalue>
12654 </para></entry>
12655 </row>
12656 </tbody>
12657 </tgroup>
12658 </table>
12660 <tip>
12661 <para>
12662 The <function>abbrev</function>, <function>host</function>,
12663 and <function>text</function> functions are primarily intended to offer
12664 alternative display formats for IP addresses.
12665 </para>
12666 </tip>
12668 <para>
12669 The MAC address types, <type>macaddr</type> and <type>macaddr8</type>,
12670 support the usual comparison operators shown in
12671 <xref linkend="functions-comparison-op-table"/>
12672 as well as the specialized functions shown in
12673 <xref linkend="macaddr-functions-table"/>.
12674 In addition, they support the bitwise logical operators
12675 <literal>~</literal>, <literal>&amp;</literal> and <literal>|</literal>
12676 (NOT, AND and OR), just as shown above for IP addresses.
12677 </para>
12679 <table id="macaddr-functions-table">
12680 <title>MAC Address Functions</title>
12681 <tgroup cols="1">
12682 <thead>
12683 <row>
12684 <entry role="func_table_entry"><para role="func_signature">
12685 Function
12686 </para>
12687 <para>
12688 Description
12689 </para>
12690 <para>
12691 Example(s)
12692 </para></entry>
12693 </row>
12694 </thead>
12696 <tbody>
12697 <row>
12698 <entry role="func_table_entry"><para role="func_signature">
12699 <indexterm>
12700 <primary>trunc</primary>
12701 </indexterm>
12702 <function>trunc</function> ( <type>macaddr</type> )
12703 <returnvalue>macaddr</returnvalue>
12704 </para>
12705 <para>
12706 Sets the last 3 bytes of the address to zero. The remaining prefix
12707 can be associated with a particular manufacturer (using data not
12708 included in <productname>PostgreSQL</productname>).
12709 </para>
12710 <para>
12711 <literal>trunc(macaddr '12:34:56:78:90:ab')</literal>
12712 <returnvalue>12:34:56:00:00:00</returnvalue>
12713 </para></entry>
12714 </row>
12716 <row>
12717 <entry role="func_table_entry"><para role="func_signature">
12718 <function>trunc</function> ( <type>macaddr8</type> )
12719 <returnvalue>macaddr8</returnvalue>
12720 </para>
12721 <para>
12722 Sets the last 5 bytes of the address to zero. The remaining prefix
12723 can be associated with a particular manufacturer (using data not
12724 included in <productname>PostgreSQL</productname>).
12725 </para>
12726 <para>
12727 <literal>trunc(macaddr8 '12:34:56:78:90:ab:cd:ef')</literal>
12728 <returnvalue>12:34:56:00:00:00:00:00</returnvalue>
12729 </para></entry>
12730 </row>
12732 <row>
12733 <entry role="func_table_entry"><para role="func_signature">
12734 <indexterm>
12735 <primary>macaddr8_set7bit</primary>
12736 </indexterm>
12737 <function>macaddr8_set7bit</function> ( <type>macaddr8</type> )
12738 <returnvalue>macaddr8</returnvalue>
12739 </para>
12740 <para>
12741 Sets the 7th bit of the address to one, creating what is known as
12742 modified EUI-64, for inclusion in an IPv6 address.
12743 </para>
12744 <para>
12745 <literal>macaddr8_set7bit(macaddr8 '00:34:56:ab:cd:ef')</literal>
12746 <returnvalue>02:34:56:ff:fe:ab:cd:ef</returnvalue>
12747 </para></entry>
12748 </row>
12749 </tbody>
12750 </tgroup>
12751 </table>
12753 </sect1>
12756 <sect1 id="functions-textsearch">
12757 <title>Text Search Functions and Operators</title>
12759 <indexterm zone="datatype-textsearch">
12760 <primary>full text search</primary>
12761 <secondary>functions and operators</secondary>
12762 </indexterm>
12764 <indexterm zone="datatype-textsearch">
12765 <primary>text search</primary>
12766 <secondary>functions and operators</secondary>
12767 </indexterm>
12769 <para>
12770 <xref linkend="textsearch-operators-table"/>,
12771 <xref linkend="textsearch-functions-table"/> and
12772 <xref linkend="textsearch-functions-debug-table"/>
12773 summarize the functions and operators that are provided
12774 for full text searching. See <xref linkend="textsearch"/> for a detailed
12775 explanation of <productname>PostgreSQL</productname>'s text search
12776 facility.
12777 </para>
12779 <table id="textsearch-operators-table">
12780 <title>Text Search Operators</title>
12781 <tgroup cols="1">
12782 <thead>
12783 <row>
12784 <entry role="func_table_entry"><para role="func_signature">
12785 Operator
12786 </para>
12787 <para>
12788 Description
12789 </para>
12790 <para>
12791 Example(s)
12792 </para></entry>
12793 </row>
12794 </thead>
12796 <tbody>
12797 <row>
12798 <entry role="func_table_entry"><para role="func_signature">
12799 <type>tsvector</type> <literal>@@</literal> <type>tsquery</type>
12800 <returnvalue>boolean</returnvalue>
12801 </para>
12802 <para role="func_signature">
12803 <type>tsquery</type> <literal>@@</literal> <type>tsvector</type>
12804 <returnvalue>boolean</returnvalue>
12805 </para>
12806 <para>
12807 Does <type>tsvector</type> match <type>tsquery</type>?
12808 (The arguments can be given in either order.)
12809 </para>
12810 <para>
12811 <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat &amp; rat')</literal>
12812 <returnvalue>t</returnvalue>
12813 </para></entry>
12814 </row>
12816 <row>
12817 <entry role="func_table_entry"><para role="func_signature">
12818 <type>text</type> <literal>@@</literal> <type>tsquery</type>
12819 <returnvalue>boolean</returnvalue>
12820 </para>
12821 <para>
12822 Does text string, after implicit invocation
12823 of <function>to_tsvector()</function>, match <type>tsquery</type>?
12824 </para>
12825 <para>
12826 <literal>'fat cats ate rats' @@ to_tsquery('cat &amp; rat')</literal>
12827 <returnvalue>t</returnvalue>
12828 </para></entry>
12829 </row>
12831 <row>
12832 <entry role="func_table_entry"><para role="func_signature">
12833 <type>tsvector</type> <literal>@@@</literal> <type>tsquery</type>
12834 <returnvalue>boolean</returnvalue>
12835 </para>
12836 <para role="func_signature">
12837 <type>tsquery</type> <literal>@@@</literal> <type>tsvector</type>
12838 <returnvalue>boolean</returnvalue>
12839 </para>
12840 <para>
12841 This is a deprecated synonym for <literal>@@</literal>.
12842 </para>
12843 <para>
12844 <literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat &amp; rat')</literal>
12845 <returnvalue>t</returnvalue>
12846 </para></entry>
12847 </row>
12849 <row>
12850 <entry role="func_table_entry"><para role="func_signature">
12851 <type>tsvector</type> <literal>||</literal> <type>tsvector</type>
12852 <returnvalue>tsvector</returnvalue>
12853 </para>
12854 <para>
12855 Concatenates two <type>tsvector</type>s. If both inputs contain
12856 lexeme positions, the second input's positions are adjusted
12857 accordingly.
12858 </para>
12859 <para>
12860 <literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal>
12861 <returnvalue>'a':1 'b':2,5 'c':3 'd':4</returnvalue>
12862 </para></entry>
12863 </row>
12865 <row>
12866 <entry role="func_table_entry"><para role="func_signature">
12867 <type>tsquery</type> <literal>&amp;&amp;</literal> <type>tsquery</type>
12868 <returnvalue>tsquery</returnvalue>
12869 </para>
12870 <para>
12871 ANDs two <type>tsquery</type>s together, producing a query that
12872 matches documents that match both input queries.
12873 </para>
12874 <para>
12875 <literal>'fat | rat'::tsquery &amp;&amp; 'cat'::tsquery</literal>
12876 <returnvalue>( 'fat' | 'rat' ) &amp; 'cat'</returnvalue>
12877 </para></entry>
12878 </row>
12880 <row>
12881 <entry role="func_table_entry"><para role="func_signature">
12882 <type>tsquery</type> <literal>||</literal> <type>tsquery</type>
12883 <returnvalue>tsquery</returnvalue>
12884 </para>
12885 <para>
12886 ORs two <type>tsquery</type>s together, producing a query that
12887 matches documents that match either input query.
12888 </para>
12889 <para>
12890 <literal>'fat | rat'::tsquery || 'cat'::tsquery</literal>
12891 <returnvalue>'fat' | 'rat' | 'cat'</returnvalue>
12892 </para></entry>
12893 </row>
12895 <row>
12896 <entry role="func_table_entry"><para role="func_signature">
12897 <literal>!!</literal> <type>tsquery</type>
12898 <returnvalue>tsquery</returnvalue>
12899 </para>
12900 <para>
12901 Negates a <type>tsquery</type>, producing a query that matches
12902 documents that do not match the input query.
12903 </para>
12904 <para>
12905 <literal>!! 'cat'::tsquery</literal>
12906 <returnvalue>!'cat'</returnvalue>
12907 </para></entry>
12908 </row>
12910 <row>
12911 <entry role="func_table_entry"><para role="func_signature">
12912 <type>tsquery</type> <literal>&lt;-&gt;</literal> <type>tsquery</type>
12913 <returnvalue>tsquery</returnvalue>
12914 </para>
12915 <para>
12916 Constructs a phrase query, which matches if the two input queries
12917 match at successive lexemes.
12918 </para>
12919 <para>
12920 <literal>to_tsquery('fat') &lt;-&gt; to_tsquery('rat')</literal>
12921 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
12922 </para></entry>
12923 </row>
12925 <row>
12926 <entry role="func_table_entry"><para role="func_signature">
12927 <type>tsquery</type> <literal>@&gt;</literal> <type>tsquery</type>
12928 <returnvalue>boolean</returnvalue>
12929 </para>
12930 <para>
12931 Does first <type>tsquery</type> contain the second? (This considers
12932 only whether all the lexemes appearing in one query appear in the
12933 other, ignoring the combining operators.)
12934 </para>
12935 <para>
12936 <literal>'cat'::tsquery @&gt; 'cat &amp; rat'::tsquery</literal>
12937 <returnvalue>f</returnvalue>
12938 </para></entry>
12939 </row>
12941 <row>
12942 <entry role="func_table_entry"><para role="func_signature">
12943 <type>tsquery</type> <literal>&lt;@</literal> <type>tsquery</type>
12944 <returnvalue>boolean</returnvalue>
12945 </para>
12946 <para>
12947 Is first <type>tsquery</type> contained in the second? (This
12948 considers only whether all the lexemes appearing in one query appear
12949 in the other, ignoring the combining operators.)
12950 </para>
12951 <para>
12952 <literal>'cat'::tsquery &lt;@ 'cat &amp; rat'::tsquery</literal>
12953 <returnvalue>t</returnvalue>
12954 </para>
12955 <para>
12956 <literal>'cat'::tsquery &lt;@ '!cat &amp; rat'::tsquery</literal>
12957 <returnvalue>t</returnvalue>
12958 </para></entry>
12959 </row>
12960 </tbody>
12961 </tgroup>
12962 </table>
12964 <para>
12965 In addition to these specialized operators, the usual comparison
12966 operators shown in <xref linkend="functions-comparison-op-table"/> are
12967 available for types <type>tsvector</type> and <type>tsquery</type>.
12968 These are not very
12969 useful for text searching but allow, for example, unique indexes to be
12970 built on columns of these types.
12971 </para>
12973 <table id="textsearch-functions-table">
12974 <title>Text Search Functions</title>
12975 <tgroup cols="1">
12976 <thead>
12977 <row>
12978 <entry role="func_table_entry"><para role="func_signature">
12979 Function
12980 </para>
12981 <para>
12982 Description
12983 </para>
12984 <para>
12985 Example(s)
12986 </para></entry>
12987 </row>
12988 </thead>
12990 <tbody>
12991 <row>
12992 <entry role="func_table_entry"><para role="func_signature">
12993 <indexterm>
12994 <primary>array_to_tsvector</primary>
12995 </indexterm>
12996 <function>array_to_tsvector</function> ( <type>text[]</type> )
12997 <returnvalue>tsvector</returnvalue>
12998 </para>
12999 <para>
13000 Converts an array of text strings to a <type>tsvector</type>.
13001 The given strings are used as lexemes as-is, without further
13002 processing. Array elements must not be empty strings
13003 or <literal>NULL</literal>.
13004 </para>
13005 <para>
13006 <literal>array_to_tsvector('{fat,cat,rat}'::text[])</literal>
13007 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13008 </para></entry>
13009 </row>
13011 <row>
13012 <entry role="func_table_entry"><para role="func_signature">
13013 <indexterm>
13014 <primary>get_current_ts_config</primary>
13015 </indexterm>
13016 <function>get_current_ts_config</function> ( )
13017 <returnvalue>regconfig</returnvalue>
13018 </para>
13019 <para>
13020 Returns the OID of the current default text search configuration
13021 (as set by <xref linkend="guc-default-text-search-config"/>).
13022 </para>
13023 <para>
13024 <literal>get_current_ts_config()</literal>
13025 <returnvalue>english</returnvalue>
13026 </para></entry>
13027 </row>
13029 <row>
13030 <entry role="func_table_entry"><para role="func_signature">
13031 <indexterm>
13032 <primary>length</primary>
13033 </indexterm>
13034 <function>length</function> ( <type>tsvector</type> )
13035 <returnvalue>integer</returnvalue>
13036 </para>
13037 <para>
13038 Returns the number of lexemes in the <type>tsvector</type>.
13039 </para>
13040 <para>
13041 <literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13042 <returnvalue>3</returnvalue>
13043 </para></entry>
13044 </row>
13046 <row>
13047 <entry role="func_table_entry"><para role="func_signature">
13048 <indexterm>
13049 <primary>numnode</primary>
13050 </indexterm>
13051 <function>numnode</function> ( <type>tsquery</type> )
13052 <returnvalue>integer</returnvalue>
13053 </para>
13054 <para>
13055 Returns the number of lexemes plus operators in
13056 the <type>tsquery</type>.
13057 </para>
13058 <para>
13059 <literal>numnode('(fat &amp; rat) | cat'::tsquery)</literal>
13060 <returnvalue>5</returnvalue>
13061 </para></entry>
13062 </row>
13064 <row>
13065 <entry role="func_table_entry"><para role="func_signature">
13066 <indexterm>
13067 <primary>plainto_tsquery</primary>
13068 </indexterm>
13069 <function>plainto_tsquery</function> (
13070 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13071 <parameter>query</parameter> <type>text</type> )
13072 <returnvalue>tsquery</returnvalue>
13073 </para>
13074 <para>
13075 Converts text to a <type>tsquery</type>, normalizing words according to
13076 the specified or default configuration. Any punctuation in the string
13077 is ignored (it does not determine query operators). The resulting
13078 query matches documents containing all non-stopwords in the text.
13079 </para>
13080 <para>
13081 <literal>plainto_tsquery('english', 'The Fat Rats')</literal>
13082 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13083 </para></entry>
13084 </row>
13086 <row>
13087 <entry role="func_table_entry"><para role="func_signature">
13088 <indexterm>
13089 <primary>phraseto_tsquery</primary>
13090 </indexterm>
13091 <function>phraseto_tsquery</function> (
13092 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13093 <parameter>query</parameter> <type>text</type> )
13094 <returnvalue>tsquery</returnvalue>
13095 </para>
13096 <para>
13097 Converts text to a <type>tsquery</type>, normalizing words according to
13098 the specified or default configuration. Any punctuation in the string
13099 is ignored (it does not determine query operators). The resulting
13100 query matches phrases containing all non-stopwords in the text.
13101 </para>
13102 <para>
13103 <literal>phraseto_tsquery('english', 'The Fat Rats')</literal>
13104 <returnvalue>'fat' &lt;-&gt; 'rat'</returnvalue>
13105 </para>
13106 <para>
13107 <literal>phraseto_tsquery('english', 'The Cat and Rats')</literal>
13108 <returnvalue>'cat' &lt;2&gt; 'rat'</returnvalue>
13109 </para></entry>
13110 </row>
13112 <row>
13113 <entry role="func_table_entry"><para role="func_signature">
13114 <indexterm>
13115 <primary>websearch_to_tsquery</primary>
13116 </indexterm>
13117 <function>websearch_to_tsquery</function> (
13118 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13119 <parameter>query</parameter> <type>text</type> )
13120 <returnvalue>tsquery</returnvalue>
13121 </para>
13122 <para>
13123 Converts text to a <type>tsquery</type>, normalizing words according
13124 to the specified or default configuration. Quoted word sequences are
13125 converted to phrase tests. The word <quote>or</quote> is understood
13126 as producing an OR operator, and a dash produces a NOT operator;
13127 other punctuation is ignored.
13128 This approximates the behavior of some common web search tools.
13129 </para>
13130 <para>
13131 <literal>websearch_to_tsquery('english', '"fat rat" or cat dog')</literal>
13132 <returnvalue>'fat' &lt;-&gt; 'rat' | 'cat' &amp; 'dog'</returnvalue>
13133 </para></entry>
13134 </row>
13136 <row>
13137 <entry role="func_table_entry"><para role="func_signature">
13138 <indexterm>
13139 <primary>querytree</primary>
13140 </indexterm>
13141 <function>querytree</function> ( <type>tsquery</type> )
13142 <returnvalue>text</returnvalue>
13143 </para>
13144 <para>
13145 Produces a representation of the indexable portion of
13146 a <type>tsquery</type>. A result that is empty or
13147 just <literal>T</literal> indicates a non-indexable query.
13148 </para>
13149 <para>
13150 <literal>querytree('foo &amp; ! bar'::tsquery)</literal>
13151 <returnvalue>'foo'</returnvalue>
13152 </para></entry>
13153 </row>
13155 <row>
13156 <entry role="func_table_entry"><para role="func_signature">
13157 <indexterm>
13158 <primary>setweight</primary>
13159 </indexterm>
13160 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type> )
13161 <returnvalue>tsvector</returnvalue>
13162 </para>
13163 <para>
13164 Assigns the specified <parameter>weight</parameter> to each element
13165 of the <parameter>vector</parameter>.
13166 </para>
13167 <para>
13168 <literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal>
13169 <returnvalue>'cat':3A 'fat':2A,4A 'rat':5A</returnvalue>
13170 </para></entry>
13171 </row>
13173 <row>
13174 <entry role="func_table_entry"><para role="func_signature">
13175 <indexterm>
13176 <primary>setweight</primary>
13177 <secondary>setweight for specific lexeme(s)</secondary>
13178 </indexterm>
13179 <function>setweight</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weight</parameter> <type>"char"</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13180 <returnvalue>tsvector</returnvalue>
13181 </para>
13182 <para>
13183 Assigns the specified <parameter>weight</parameter> to elements
13184 of the <parameter>vector</parameter> that are listed
13185 in <parameter>lexemes</parameter>.
13186 The strings in <parameter>lexemes</parameter> are taken as lexemes
13187 as-is, without further processing. Strings that do not match any
13188 lexeme in <parameter>vector</parameter> are ignored.
13189 </para>
13190 <para>
13191 <literal>setweight('fat:2,4 cat:3 rat:5,6B'::tsvector, 'A', '{cat,rat}')</literal>
13192 <returnvalue>'cat':3A 'fat':2,4 'rat':5A,6A</returnvalue>
13193 </para></entry>
13194 </row>
13196 <row>
13197 <entry role="func_table_entry"><para role="func_signature">
13198 <indexterm>
13199 <primary>strip</primary>
13200 </indexterm>
13201 <function>strip</function> ( <type>tsvector</type> )
13202 <returnvalue>tsvector</returnvalue>
13203 </para>
13204 <para>
13205 Removes positions and weights from the <type>tsvector</type>.
13206 </para>
13207 <para>
13208 <literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13209 <returnvalue>'cat' 'fat' 'rat'</returnvalue>
13210 </para></entry>
13211 </row>
13213 <row>
13214 <entry role="func_table_entry"><para role="func_signature">
13215 <indexterm>
13216 <primary>to_tsquery</primary>
13217 </indexterm>
13218 <function>to_tsquery</function> (
13219 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13220 <parameter>query</parameter> <type>text</type> )
13221 <returnvalue>tsquery</returnvalue>
13222 </para>
13223 <para>
13224 Converts text to a <type>tsquery</type>, normalizing words according to
13225 the specified or default configuration. The words must be combined
13226 by valid <type>tsquery</type> operators.
13227 </para>
13228 <para>
13229 <literal>to_tsquery('english', 'The &amp; Fat &amp; Rats')</literal>
13230 <returnvalue>'fat' &amp; 'rat'</returnvalue>
13231 </para></entry>
13232 </row>
13234 <row>
13235 <entry role="func_table_entry"><para role="func_signature">
13236 <indexterm>
13237 <primary>to_tsvector</primary>
13238 </indexterm>
13239 <function>to_tsvector</function> (
13240 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13241 <parameter>document</parameter> <type>text</type> )
13242 <returnvalue>tsvector</returnvalue>
13243 </para>
13244 <para>
13245 Converts text to a <type>tsvector</type>, normalizing words according
13246 to the specified or default configuration. Position information is
13247 included in the result.
13248 </para>
13249 <para>
13250 <literal>to_tsvector('english', 'The Fat Rats')</literal>
13251 <returnvalue>'fat':2 'rat':3</returnvalue>
13252 </para></entry>
13253 </row>
13255 <row>
13256 <entry role="func_table_entry"><para role="func_signature">
13257 <function>to_tsvector</function> (
13258 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13259 <parameter>document</parameter> <type>json</type> )
13260 <returnvalue>tsvector</returnvalue>
13261 </para>
13262 <para role="func_signature">
13263 <function>to_tsvector</function> (
13264 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13265 <parameter>document</parameter> <type>jsonb</type> )
13266 <returnvalue>tsvector</returnvalue>
13267 </para>
13268 <para>
13269 Converts each string value in the JSON document to
13270 a <type>tsvector</type>, normalizing words according to the specified
13271 or default configuration. The results are then concatenated in
13272 document order to produce the output. Position information is
13273 generated as though one stopword exists between each pair of string
13274 values. (Beware that <quote>document order</quote> of the fields of a
13275 JSON object is implementation-dependent when the input
13276 is <type>jsonb</type>; observe the difference in the examples.)
13277 </para>
13278 <para>
13279 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::json)</literal>
13280 <returnvalue>'dog':5 'fat':2 'rat':3</returnvalue>
13281 </para>
13282 <para>
13283 <literal>to_tsvector('english', '{"aa": "The Fat Rats", "b": "dog"}'::jsonb)</literal>
13284 <returnvalue>'dog':1 'fat':4 'rat':5</returnvalue>
13285 </para></entry>
13286 </row>
13288 <row>
13289 <entry role="func_table_entry"><para role="func_signature">
13290 <indexterm>
13291 <primary>json_to_tsvector</primary>
13292 </indexterm>
13293 <function>json_to_tsvector</function> (
13294 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13295 <parameter>document</parameter> <type>json</type>,
13296 <parameter>filter</parameter> <type>jsonb</type> )
13297 <returnvalue>tsvector</returnvalue>
13298 </para>
13299 <para role="func_signature">
13300 <indexterm>
13301 <primary>jsonb_to_tsvector</primary>
13302 </indexterm>
13303 <function>jsonb_to_tsvector</function> (
13304 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13305 <parameter>document</parameter> <type>jsonb</type>,
13306 <parameter>filter</parameter> <type>jsonb</type> )
13307 <returnvalue>tsvector</returnvalue>
13308 </para>
13309 <para>
13310 Selects each item in the JSON document that is requested by
13311 the <parameter>filter</parameter> and converts each one to
13312 a <type>tsvector</type>, normalizing words according to the specified
13313 or default configuration. The results are then concatenated in
13314 document order to produce the output. Position information is
13315 generated as though one stopword exists between each pair of selected
13316 items. (Beware that <quote>document order</quote> of the fields of a
13317 JSON object is implementation-dependent when the input
13318 is <type>jsonb</type>.)
13319 The <parameter>filter</parameter> must be a <type>jsonb</type>
13320 array containing zero or more of these keywords:
13321 <literal>"string"</literal> (to include all string values),
13322 <literal>"numeric"</literal> (to include all numeric values),
13323 <literal>"boolean"</literal> (to include all boolean values),
13324 <literal>"key"</literal> (to include all keys), or
13325 <literal>"all"</literal> (to include all the above).
13326 As a special case, the <parameter>filter</parameter> can also be a
13327 simple JSON value that is one of these keywords.
13328 </para>
13329 <para>
13330 <literal>json_to_tsvector('english', '{"a": "The Fat Rats", "b": 123}'::json, '["string", "numeric"]')</literal>
13331 <returnvalue>'123':5 'fat':2 'rat':3</returnvalue>
13332 </para>
13333 <para>
13334 <literal>json_to_tsvector('english', '{"cat": "The Fat Rats", "dog": 123}'::json, '"all"')</literal>
13335 <returnvalue>'123':9 'cat':1 'dog':7 'fat':4 'rat':5</returnvalue>
13336 </para></entry>
13337 </row>
13339 <row>
13340 <entry role="func_table_entry"><para role="func_signature">
13341 <indexterm>
13342 <primary>ts_delete</primary>
13343 </indexterm>
13344 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexeme</parameter> <type>text</type> )
13345 <returnvalue>tsvector</returnvalue>
13346 </para>
13347 <para>
13348 Removes any occurrence of the given <parameter>lexeme</parameter>
13349 from the <parameter>vector</parameter>.
13350 The <parameter>lexeme</parameter> string is treated as a lexeme as-is,
13351 without further processing.
13352 </para>
13353 <para>
13354 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, 'fat')</literal>
13355 <returnvalue>'cat':3 'rat':5A</returnvalue>
13356 </para></entry>
13357 </row>
13359 <row>
13360 <entry role="func_table_entry"><para role="func_signature">
13361 <function>ts_delete</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>lexemes</parameter> <type>text[]</type> )
13362 <returnvalue>tsvector</returnvalue>
13363 </para>
13364 <para>
13365 Removes any occurrences of the lexemes
13366 in <parameter>lexemes</parameter>
13367 from the <parameter>vector</parameter>.
13368 The strings in <parameter>lexemes</parameter> are taken as lexemes
13369 as-is, without further processing. Strings that do not match any
13370 lexeme in <parameter>vector</parameter> are ignored.
13371 </para>
13372 <para>
13373 <literal>ts_delete('fat:2,4 cat:3 rat:5A'::tsvector, ARRAY['fat','rat'])</literal>
13374 <returnvalue>'cat':3</returnvalue>
13375 </para></entry>
13376 </row>
13378 <row>
13379 <entry role="func_table_entry"><para role="func_signature">
13380 <indexterm>
13381 <primary>ts_filter</primary>
13382 </indexterm>
13383 <function>ts_filter</function> ( <parameter>vector</parameter> <type>tsvector</type>, <parameter>weights</parameter> <type>"char"[]</type> )
13384 <returnvalue>tsvector</returnvalue>
13385 </para>
13386 <para>
13387 Selects only elements with the given <parameter>weights</parameter>
13388 from the <parameter>vector</parameter>.
13389 </para>
13390 <para>
13391 <literal>ts_filter('fat:2,4 cat:3b,7c rat:5A'::tsvector, '{a,b}')</literal>
13392 <returnvalue>'cat':3B 'rat':5A</returnvalue>
13393 </para></entry>
13394 </row>
13396 <row>
13397 <entry role="func_table_entry"><para role="func_signature">
13398 <indexterm>
13399 <primary>ts_headline</primary>
13400 </indexterm>
13401 <function>ts_headline</function> (
13402 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13403 <parameter>document</parameter> <type>text</type>,
13404 <parameter>query</parameter> <type>tsquery</type>
13405 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13406 <returnvalue>text</returnvalue>
13407 </para>
13408 <para>
13409 Displays, in an abbreviated form, the match(es) for
13410 the <parameter>query</parameter> in
13411 the <parameter>document</parameter>, which must be raw text not
13412 a <type>tsvector</type>. Words in the document are normalized
13413 according to the specified or default configuration before matching to
13414 the query. Use of this function is discussed in
13415 <xref linkend="textsearch-headline"/>, which also describes the
13416 available <parameter>options</parameter>.
13417 </para>
13418 <para>
13419 <literal>ts_headline('The fat cat ate the rat.', 'cat')</literal>
13420 <returnvalue>The fat &lt;b&gt;cat&lt;/b&gt; ate the rat.</returnvalue>
13421 </para></entry>
13422 </row>
13424 <row>
13425 <entry role="func_table_entry"><para role="func_signature">
13426 <function>ts_headline</function> (
13427 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13428 <parameter>document</parameter> <type>json</type>,
13429 <parameter>query</parameter> <type>tsquery</type>
13430 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13431 <returnvalue>text</returnvalue>
13432 </para>
13433 <para role="func_signature">
13434 <function>ts_headline</function> (
13435 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13436 <parameter>document</parameter> <type>jsonb</type>,
13437 <parameter>query</parameter> <type>tsquery</type>
13438 <optional>, <parameter>options</parameter> <type>text</type> </optional> )
13439 <returnvalue>text</returnvalue>
13440 </para>
13441 <para>
13442 Displays, in an abbreviated form, match(es) for
13443 the <parameter>query</parameter> that occur in string values
13444 within the JSON <parameter>document</parameter>.
13445 See <xref linkend="textsearch-headline"/> for more details.
13446 </para>
13447 <para>
13448 <literal>ts_headline('{"cat":"raining cats and dogs"}'::jsonb, 'cat')</literal>
13449 <returnvalue>{"cat": "raining &lt;b&gt;cats&lt;/b&gt; and dogs"}</returnvalue>
13450 </para></entry>
13451 </row>
13453 <row>
13454 <entry role="func_table_entry"><para role="func_signature">
13455 <indexterm>
13456 <primary>ts_rank</primary>
13457 </indexterm>
13458 <function>ts_rank</function> (
13459 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13460 <parameter>vector</parameter> <type>tsvector</type>,
13461 <parameter>query</parameter> <type>tsquery</type>
13462 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13463 <returnvalue>real</returnvalue>
13464 </para>
13465 <para>
13466 Computes a score showing how well
13467 the <parameter>vector</parameter> matches
13468 the <parameter>query</parameter>. See
13469 <xref linkend="textsearch-ranking"/> for details.
13470 </para>
13471 <para>
13472 <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')</literal>
13473 <returnvalue>0.06079271</returnvalue>
13474 </para></entry>
13475 </row>
13477 <row>
13478 <entry role="func_table_entry"><para role="func_signature">
13479 <indexterm>
13480 <primary>ts_rank_cd</primary>
13481 </indexterm>
13482 <function>ts_rank_cd</function> (
13483 <optional> <parameter>weights</parameter> <type>real[]</type>, </optional>
13484 <parameter>vector</parameter> <type>tsvector</type>,
13485 <parameter>query</parameter> <type>tsquery</type>
13486 <optional>, <parameter>normalization</parameter> <type>integer</type> </optional> )
13487 <returnvalue>real</returnvalue>
13488 </para>
13489 <para>
13490 Computes a score showing how well
13491 the <parameter>vector</parameter> matches
13492 the <parameter>query</parameter>, using a cover density
13493 algorithm. See <xref linkend="textsearch-ranking"/> for details.
13494 </para>
13495 <para>
13496 <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')</literal>
13497 <returnvalue>0.1</returnvalue>
13498 </para></entry>
13499 </row>
13501 <row>
13502 <entry role="func_table_entry"><para role="func_signature">
13503 <indexterm>
13504 <primary>ts_rewrite</primary>
13505 </indexterm>
13506 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13507 <parameter>target</parameter> <type>tsquery</type>,
13508 <parameter>substitute</parameter> <type>tsquery</type> )
13509 <returnvalue>tsquery</returnvalue>
13510 </para>
13511 <para>
13512 Replaces occurrences of <parameter>target</parameter>
13513 with <parameter>substitute</parameter>
13514 within the <parameter>query</parameter>.
13515 See <xref linkend="textsearch-query-rewriting"/> for details.
13516 </para>
13517 <para>
13518 <literal>ts_rewrite('a &amp; b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal>
13519 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13520 </para></entry>
13521 </row>
13523 <row>
13524 <entry role="func_table_entry"><para role="func_signature">
13525 <function>ts_rewrite</function> ( <parameter>query</parameter> <type>tsquery</type>,
13526 <parameter>select</parameter> <type>text</type> )
13527 <returnvalue>tsquery</returnvalue>
13528 </para>
13529 <para>
13530 Replaces portions of the <parameter>query</parameter> according to
13531 target(s) and substitute(s) obtained by executing
13532 a <command>SELECT</command> command.
13533 See <xref linkend="textsearch-query-rewriting"/> for details.
13534 </para>
13535 <para>
13536 <literal>SELECT ts_rewrite('a &amp; b'::tsquery, 'SELECT t,s FROM aliases')</literal>
13537 <returnvalue>'b' &amp; ( 'foo' | 'bar' )</returnvalue>
13538 </para></entry>
13539 </row>
13541 <row>
13542 <entry role="func_table_entry"><para role="func_signature">
13543 <indexterm>
13544 <primary>tsquery_phrase</primary>
13545 </indexterm>
13546 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type> )
13547 <returnvalue>tsquery</returnvalue>
13548 </para>
13549 <para>
13550 Constructs a phrase query that searches
13551 for matches of <parameter>query1</parameter>
13552 and <parameter>query2</parameter> at successive lexemes (same
13553 as <literal>&lt;-&gt;</literal> operator).
13554 </para>
13555 <para>
13556 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))</literal>
13557 <returnvalue>'fat' &lt;-&gt; 'cat'</returnvalue>
13558 </para></entry>
13559 </row>
13561 <row>
13562 <entry role="func_table_entry"><para role="func_signature">
13563 <function>tsquery_phrase</function> ( <parameter>query1</parameter> <type>tsquery</type>, <parameter>query2</parameter> <type>tsquery</type>, <parameter>distance</parameter> <type>integer</type> )
13564 <returnvalue>tsquery</returnvalue>
13565 </para>
13566 <para>
13567 Constructs a phrase query that searches
13568 for matches of <parameter>query1</parameter> and
13569 <parameter>query2</parameter> that occur exactly
13570 <parameter>distance</parameter> lexemes apart.
13571 </para>
13572 <para>
13573 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'), 10)</literal>
13574 <returnvalue>'fat' &lt;10&gt; 'cat'</returnvalue>
13575 </para></entry>
13576 </row>
13578 <row>
13579 <entry role="func_table_entry"><para role="func_signature">
13580 <indexterm>
13581 <primary>tsvector_to_array</primary>
13582 </indexterm>
13583 <function>tsvector_to_array</function> ( <type>tsvector</type> )
13584 <returnvalue>text[]</returnvalue>
13585 </para>
13586 <para>
13587 Converts a <type>tsvector</type> to an array of lexemes.
13588 </para>
13589 <para>
13590 <literal>tsvector_to_array('fat:2,4 cat:3 rat:5A'::tsvector)</literal>
13591 <returnvalue>{cat,fat,rat}</returnvalue>
13592 </para></entry>
13593 </row>
13595 <row>
13596 <entry role="func_table_entry"><para role="func_signature">
13597 <indexterm>
13598 <primary>unnest</primary>
13599 <secondary>for tsvector</secondary>
13600 </indexterm>
13601 <function>unnest</function> ( <type>tsvector</type> )
13602 <returnvalue>setof record</returnvalue>
13603 ( <parameter>lexeme</parameter> <type>text</type>,
13604 <parameter>positions</parameter> <type>smallint[]</type>,
13605 <parameter>weights</parameter> <type>text</type> )
13606 </para>
13607 <para>
13608 Expands a <type>tsvector</type> into a set of rows, one per lexeme.
13609 </para>
13610 <para>
13611 <literal>select * from unnest('cat:3 fat:2,4 rat:5A'::tsvector)</literal>
13612 <returnvalue></returnvalue>
13613 <programlisting>
13614 lexeme | positions | weights
13615 --------+-----------+---------
13616 cat | {3} | {D}
13617 fat | {2,4} | {D,D}
13618 rat | {5} | {A}
13619 </programlisting>
13620 </para></entry>
13621 </row>
13622 </tbody>
13623 </tgroup>
13624 </table>
13626 <note>
13627 <para>
13628 All the text search functions that accept an optional <type>regconfig</type>
13629 argument will use the configuration specified by
13630 <xref linkend="guc-default-text-search-config"/>
13631 when that argument is omitted.
13632 </para>
13633 </note>
13635 <para>
13636 The functions in
13637 <xref linkend="textsearch-functions-debug-table"/>
13638 are listed separately because they are not usually used in everyday text
13639 searching operations. They are primarily helpful for development and
13640 debugging of new text search configurations.
13641 </para>
13643 <table id="textsearch-functions-debug-table">
13644 <title>Text Search Debugging Functions</title>
13645 <tgroup cols="1">
13646 <thead>
13647 <row>
13648 <entry role="func_table_entry"><para role="func_signature">
13649 Function
13650 </para>
13651 <para>
13652 Description
13653 </para>
13654 <para>
13655 Example(s)
13656 </para></entry>
13657 </row>
13658 </thead>
13660 <tbody>
13661 <row>
13662 <entry role="func_table_entry"><para role="func_signature">
13663 <indexterm>
13664 <primary>ts_debug</primary>
13665 </indexterm>
13666 <function>ts_debug</function> (
13667 <optional> <parameter>config</parameter> <type>regconfig</type>, </optional>
13668 <parameter>document</parameter> <type>text</type> )
13669 <returnvalue>setof record</returnvalue>
13670 ( <parameter>alias</parameter> <type>text</type>,
13671 <parameter>description</parameter> <type>text</type>,
13672 <parameter>token</parameter> <type>text</type>,
13673 <parameter>dictionaries</parameter> <type>regdictionary[]</type>,
13674 <parameter>dictionary</parameter> <type>regdictionary</type>,
13675 <parameter>lexemes</parameter> <type>text[]</type> )
13676 </para>
13677 <para>
13678 Extracts and normalizes tokens from
13679 the <parameter>document</parameter> according to the specified or
13680 default text search configuration, and returns information about how
13681 each token was processed.
13682 See <xref linkend="textsearch-configuration-testing"/> for details.
13683 </para>
13684 <para>
13685 <literal>ts_debug('english', 'The Brightest supernovaes')</literal>
13686 <returnvalue>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</returnvalue>
13687 </para></entry>
13688 </row>
13690 <row>
13691 <entry role="func_table_entry"><para role="func_signature">
13692 <indexterm>
13693 <primary>ts_lexize</primary>
13694 </indexterm>
13695 <function>ts_lexize</function> ( <parameter>dict</parameter> <type>regdictionary</type>, <parameter>token</parameter> <type>text</type> )
13696 <returnvalue>text[]</returnvalue>
13697 </para>
13698 <para>
13699 Returns an array of replacement lexemes if the input token is known to
13700 the dictionary, or an empty array if the token is known to the
13701 dictionary but it is a stop word, or NULL if it is not a known word.
13702 See <xref linkend="textsearch-dictionary-testing"/> for details.
13703 </para>
13704 <para>
13705 <literal>ts_lexize('english_stem', 'stars')</literal>
13706 <returnvalue>{star}</returnvalue>
13707 </para></entry>
13708 </row>
13710 <row>
13711 <entry role="func_table_entry"><para role="func_signature">
13712 <indexterm>
13713 <primary>ts_parse</primary>
13714 </indexterm>
13715 <function>ts_parse</function> ( <parameter>parser_name</parameter> <type>text</type>,
13716 <parameter>document</parameter> <type>text</type> )
13717 <returnvalue>setof record</returnvalue>
13718 ( <parameter>tokid</parameter> <type>integer</type>,
13719 <parameter>token</parameter> <type>text</type> )
13720 </para>
13721 <para>
13722 Extracts tokens from the <parameter>document</parameter> using the
13723 named parser.
13724 See <xref linkend="textsearch-parser-testing"/> for details.
13725 </para>
13726 <para>
13727 <literal>ts_parse('default', 'foo - bar')</literal>
13728 <returnvalue>(1,foo) ...</returnvalue>
13729 </para></entry>
13730 </row>
13732 <row>
13733 <entry role="func_table_entry"><para role="func_signature">
13734 <function>ts_parse</function> ( <parameter>parser_oid</parameter> <type>oid</type>,
13735 <parameter>document</parameter> <type>text</type> )
13736 <returnvalue>setof record</returnvalue>
13737 ( <parameter>tokid</parameter> <type>integer</type>,
13738 <parameter>token</parameter> <type>text</type> )
13739 </para>
13740 <para>
13741 Extracts tokens from the <parameter>document</parameter> using a
13742 parser specified by OID.
13743 See <xref linkend="textsearch-parser-testing"/> for details.
13744 </para>
13745 <para>
13746 <literal>ts_parse(3722, 'foo - bar')</literal>
13747 <returnvalue>(1,foo) ...</returnvalue>
13748 </para></entry>
13749 </row>
13751 <row>
13752 <entry role="func_table_entry"><para role="func_signature">
13753 <indexterm>
13754 <primary>ts_token_type</primary>
13755 </indexterm>
13756 <function>ts_token_type</function> ( <parameter>parser_name</parameter> <type>text</type> )
13757 <returnvalue>setof record</returnvalue>
13758 ( <parameter>tokid</parameter> <type>integer</type>,
13759 <parameter>alias</parameter> <type>text</type>,
13760 <parameter>description</parameter> <type>text</type> )
13761 </para>
13762 <para>
13763 Returns a table that describes each type of token the named parser can
13764 recognize.
13765 See <xref linkend="textsearch-parser-testing"/> for details.
13766 </para>
13767 <para>
13768 <literal>ts_token_type('default')</literal>
13769 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
13770 </para></entry>
13771 </row>
13773 <row>
13774 <entry role="func_table_entry"><para role="func_signature">
13775 <function>ts_token_type</function> ( <parameter>parser_oid</parameter> <type>oid</type> )
13776 <returnvalue>setof record</returnvalue>
13777 ( <parameter>tokid</parameter> <type>integer</type>,
13778 <parameter>alias</parameter> <type>text</type>,
13779 <parameter>description</parameter> <type>text</type> )
13780 </para>
13781 <para>
13782 Returns a table that describes each type of token a parser specified
13783 by OID can recognize.
13784 See <xref linkend="textsearch-parser-testing"/> for details.
13785 </para>
13786 <para>
13787 <literal>ts_token_type(3722)</literal>
13788 <returnvalue>(1,asciiword,"Word, all ASCII") ...</returnvalue>
13789 </para></entry>
13790 </row>
13792 <row>
13793 <entry role="func_table_entry"><para role="func_signature">
13794 <indexterm>
13795 <primary>ts_stat</primary>
13796 </indexterm>
13797 <function>ts_stat</function> ( <parameter>sqlquery</parameter> <type>text</type>
13798 <optional>, <parameter>weights</parameter> <type>text</type> </optional> )
13799 <returnvalue>setof record</returnvalue>
13800 ( <parameter>word</parameter> <type>text</type>,
13801 <parameter>ndoc</parameter> <type>integer</type>,
13802 <parameter>nentry</parameter> <type>integer</type> )
13803 </para>
13804 <para>
13805 Executes the <parameter>sqlquery</parameter>, which must return a
13806 single <type>tsvector</type> column, and returns statistics about each
13807 distinct lexeme contained in the data.
13808 See <xref linkend="textsearch-statistics"/> for details.
13809 </para>
13810 <para>
13811 <literal>ts_stat('SELECT vector FROM apod')</literal>
13812 <returnvalue>(foo,10,15) ...</returnvalue>
13813 </para></entry>
13814 </row>
13815 </tbody>
13816 </tgroup>
13817 </table>
13819 </sect1>
13821 <sect1 id="functions-uuid">
13822 <title>UUID Functions</title>
13824 <indexterm zone="datatype-uuid">
13825 <primary>UUID</primary>
13826 <secondary>generating</secondary>
13827 </indexterm>
13829 <indexterm>
13830 <primary>gen_random_uuid</primary>
13831 </indexterm>
13833 <para>
13834 <productname>PostgreSQL</productname> includes one function to generate a UUID:
13835 <synopsis>
13836 <function>gen_random_uuid</function> () <returnvalue>uuid</returnvalue>
13837 </synopsis>
13838 This function returns a version 4 (random) UUID. This is the most commonly
13839 used type of UUID and is appropriate for most applications.
13840 </para>
13842 <para>
13843 The <xref linkend="uuid-ossp"/> module provides additional functions that
13844 implement other standard algorithms for generating UUIDs.
13845 </para>
13847 <para>
13848 <productname>PostgreSQL</productname> also provides the usual comparison
13849 operators shown in <xref linkend="functions-comparison-op-table"/> for
13850 UUIDs.
13851 </para>
13852 </sect1>
13854 <sect1 id="functions-xml">
13856 <title>XML Functions</title>
13858 <indexterm>
13859 <primary>XML Functions</primary>
13860 </indexterm>
13862 <para>
13863 The functions and function-like expressions described in this
13864 section operate on values of type <type>xml</type>. See <xref
13865 linkend="datatype-xml"/> for information about the <type>xml</type>
13866 type. The function-like expressions <function>xmlparse</function>
13867 and <function>xmlserialize</function> for converting to and from
13868 type <type>xml</type> are documented there, not in this section.
13869 </para>
13871 <para>
13872 Use of most of these functions
13873 requires <productname>PostgreSQL</productname> to have been built
13874 with <command>configure --with-libxml</command>.
13875 </para>
13877 <sect2 id="functions-producing-xml">
13878 <title>Producing XML Content</title>
13880 <para>
13881 A set of functions and function-like expressions is available for
13882 producing XML content from SQL data. As such, they are
13883 particularly suitable for formatting query results into XML
13884 documents for processing in client applications.
13885 </para>
13887 <sect3>
13888 <title><literal>xmlcomment</literal></title>
13890 <indexterm>
13891 <primary>xmlcomment</primary>
13892 </indexterm>
13894 <synopsis>
13895 <function>xmlcomment</function> ( <type>text</type> ) <returnvalue>xml</returnvalue>
13896 </synopsis>
13898 <para>
13899 The function <function>xmlcomment</function> creates an XML value
13900 containing an XML comment with the specified text as content.
13901 The text cannot contain <quote><literal>--</literal></quote> or end with a
13902 <quote><literal>-</literal></quote>, otherwise the resulting construct
13903 would not be a valid XML comment.
13904 If the argument is null, the result is null.
13905 </para>
13907 <para>
13908 Example:
13909 <screen><![CDATA[
13910 SELECT xmlcomment('hello');
13912 xmlcomment
13913 --------------
13914 <!--hello-->
13915 ]]></screen>
13916 </para>
13917 </sect3>
13919 <sect3>
13920 <title><literal>xmlconcat</literal></title>
13922 <indexterm>
13923 <primary>xmlconcat</primary>
13924 </indexterm>
13926 <synopsis>
13927 <function>xmlconcat</function> ( <type>xml</type> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
13928 </synopsis>
13930 <para>
13931 The function <function>xmlconcat</function> concatenates a list
13932 of individual XML values to create a single value containing an
13933 XML content fragment. Null values are omitted; the result is
13934 only null if there are no nonnull arguments.
13935 </para>
13937 <para>
13938 Example:
13939 <screen><![CDATA[
13940 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
13942 xmlconcat
13943 ----------------------
13944 <abc/><bar>foo</bar>
13945 ]]></screen>
13946 </para>
13948 <para>
13949 XML declarations, if present, are combined as follows. If all
13950 argument values have the same XML version declaration, that
13951 version is used in the result, else no version is used. If all
13952 argument values have the standalone declaration value
13953 <quote>yes</quote>, then that value is used in the result. If
13954 all argument values have a standalone declaration value and at
13955 least one is <quote>no</quote>, then that is used in the result.
13956 Else the result will have no standalone declaration. If the
13957 result is determined to require a standalone declaration but no
13958 version declaration, a version declaration with version 1.0 will
13959 be used because XML requires an XML declaration to contain a
13960 version declaration. Encoding declarations are ignored and
13961 removed in all cases.
13962 </para>
13964 <para>
13965 Example:
13966 <screen><![CDATA[
13967 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
13969 xmlconcat
13970 -----------------------------------
13971 <?xml version="1.1"?><foo/><bar/>
13972 ]]></screen>
13973 </para>
13974 </sect3>
13976 <sect3>
13977 <title><literal>xmlelement</literal></title>
13979 <indexterm>
13980 <primary>xmlelement</primary>
13981 </indexterm>
13983 <synopsis>
13984 <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>
13985 </synopsis>
13987 <para>
13988 The <function>xmlelement</function> expression produces an XML
13989 element with the given name, attributes, and content.
13990 The <replaceable>name</replaceable>
13991 and <replaceable>attname</replaceable> items shown in the syntax are
13992 simple identifiers, not values. The <replaceable>attvalue</replaceable>
13993 and <replaceable>content</replaceable> items are expressions, which can
13994 yield any <productname>PostgreSQL</productname> data type. The
13995 argument(s) within <literal>XMLATTRIBUTES</literal> generate attributes
13996 of the XML element; the <replaceable>content</replaceable> value(s) are
13997 concatenated to form its content.
13998 </para>
14000 <para>
14001 Examples:
14002 <screen><![CDATA[
14003 SELECT xmlelement(name foo);
14005 xmlelement
14006 ------------
14007 <foo/>
14009 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
14011 xmlelement
14012 ------------------
14013 <foo bar="xyz"/>
14015 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
14017 xmlelement
14018 -------------------------------------
14019 <foo bar="2007-01-26">content</foo>
14020 ]]></screen>
14021 </para>
14023 <para>
14024 Element and attribute names that are not valid XML names are
14025 escaped by replacing the offending characters by the sequence
14026 <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
14027 <replaceable>HHHH</replaceable> is the character's Unicode
14028 codepoint in hexadecimal notation. For example:
14029 <screen><![CDATA[
14030 SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
14032 xmlelement
14033 ----------------------------------
14034 <foo_x0024_bar a_x0026_b="xyz"/>
14035 ]]></screen>
14036 </para>
14038 <para>
14039 An explicit attribute name need not be specified if the attribute
14040 value is a column reference, in which case the column's name will
14041 be used as the attribute name by default. In other cases, the
14042 attribute must be given an explicit name. So this example is
14043 valid:
14044 <screen>
14045 CREATE TABLE test (a xml, b xml);
14046 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
14047 </screen>
14048 But these are not:
14049 <screen>
14050 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
14051 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
14052 </screen>
14053 </para>
14055 <para>
14056 Element content, if specified, will be formatted according to
14057 its data type. If the content is itself of type <type>xml</type>,
14058 complex XML documents can be constructed. For example:
14059 <screen><![CDATA[
14060 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
14061 xmlelement(name abc),
14062 xmlcomment('test'),
14063 xmlelement(name xyz));
14065 xmlelement
14066 ----------------------------------------------
14067 <foo bar="xyz"><abc/><!--test--><xyz/></foo>
14068 ]]></screen>
14070 Content of other types will be formatted into valid XML character
14071 data. This means in particular that the characters &lt;, &gt;,
14072 and &amp; will be converted to entities. Binary data (data type
14073 <type>bytea</type>) will be represented in base64 or hex
14074 encoding, depending on the setting of the configuration parameter
14075 <xref linkend="guc-xmlbinary"/>. The particular behavior for
14076 individual data types is expected to evolve in order to align the
14077 PostgreSQL mappings with those specified in SQL:2006 and later,
14078 as discussed in <xref linkend="functions-xml-limits-casts"/>.
14079 </para>
14080 </sect3>
14082 <sect3>
14083 <title><literal>xmlforest</literal></title>
14085 <indexterm>
14086 <primary>xmlforest</primary>
14087 </indexterm>
14089 <synopsis>
14090 <function>xmlforest</function> ( <replaceable>content</replaceable> <optional> <literal>AS</literal> <replaceable>name</replaceable> </optional> <optional>, ...</optional> ) <returnvalue>xml</returnvalue>
14091 </synopsis>
14093 <para>
14094 The <function>xmlforest</function> expression produces an XML
14095 forest (sequence) of elements using the given names and content.
14096 As for <function>xmlelement</function>,
14097 each <replaceable>name</replaceable> must be a simple identifier, while
14098 the <replaceable>content</replaceable> expressions can have any data
14099 type.
14100 </para>
14102 <para>
14103 Examples:
14104 <screen>
14105 SELECT xmlforest('abc' AS foo, 123 AS bar);
14107 xmlforest
14108 ------------------------------
14109 &lt;foo&gt;abc&lt;/foo&gt;&lt;bar&gt;123&lt;/bar&gt;
14112 SELECT xmlforest(table_name, column_name)
14113 FROM information_schema.columns
14114 WHERE table_schema = 'pg_catalog';
14116 xmlforest
14117 ------------------------------------&zwsp;-----------------------------------
14118 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolname&lt;/column_name&gt;
14119 &lt;table_name&gt;pg_authid&lt;/table_name&gt;&zwsp;&lt;column_name&gt;rolsuper&lt;/column_name&gt;
14121 </screen>
14123 As seen in the second example, the element name can be omitted if
14124 the content value is a column reference, in which case the column
14125 name is used by default. Otherwise, a name must be specified.
14126 </para>
14128 <para>
14129 Element names that are not valid XML names are escaped as shown
14130 for <function>xmlelement</function> above. Similarly, content
14131 data is escaped to make valid XML content, unless it is already
14132 of type <type>xml</type>.
14133 </para>
14135 <para>
14136 Note that XML forests are not valid XML documents if they consist
14137 of more than one element, so it might be useful to wrap
14138 <function>xmlforest</function> expressions in
14139 <function>xmlelement</function>.
14140 </para>
14141 </sect3>
14143 <sect3>
14144 <title><literal>xmlpi</literal></title>
14146 <indexterm>
14147 <primary>xmlpi</primary>
14148 </indexterm>
14150 <synopsis>
14151 <function>xmlpi</function> ( <literal>NAME</literal> <replaceable>name</replaceable> <optional>, <replaceable>content</replaceable> </optional> ) <returnvalue>xml</returnvalue>
14152 </synopsis>
14154 <para>
14155 The <function>xmlpi</function> expression creates an XML
14156 processing instruction.
14157 As for <function>xmlelement</function>,
14158 the <replaceable>name</replaceable> must be a simple identifier, while
14159 the <replaceable>content</replaceable> expression can have any data type.
14160 The <replaceable>content</replaceable>, if present, must not contain the
14161 character sequence <literal>?&gt;</literal>.
14162 </para>
14164 <para>
14165 Example:
14166 <screen><![CDATA[
14167 SELECT xmlpi(name php, 'echo "hello world";');
14169 xmlpi
14170 -----------------------------
14171 <?php echo "hello world";?>
14172 ]]></screen>
14173 </para>
14174 </sect3>
14176 <sect3>
14177 <title><literal>xmlroot</literal></title>
14179 <indexterm>
14180 <primary>xmlroot</primary>
14181 </indexterm>
14183 <synopsis>
14184 <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>
14185 </synopsis>
14187 <para>
14188 The <function>xmlroot</function> expression alters the properties
14189 of the root node of an XML value. If a version is specified,
14190 it replaces the value in the root node's version declaration; if a
14191 standalone setting is specified, it replaces the value in the
14192 root node's standalone declaration.
14193 </para>
14195 <para>
14196 <screen><![CDATA[
14197 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
14198 version '1.0', standalone yes);
14200 xmlroot
14201 ----------------------------------------
14202 <?xml version="1.0" standalone="yes"?>
14203 <content>abc</content>
14204 ]]></screen>
14205 </para>
14206 </sect3>
14208 <sect3 id="functions-xml-xmlagg">
14209 <title><literal>xmlagg</literal></title>
14211 <indexterm>
14212 <primary>xmlagg</primary>
14213 </indexterm>
14215 <synopsis>
14216 <function>xmlagg</function> ( <type>xml</type> ) <returnvalue>xml</returnvalue>
14217 </synopsis>
14219 <para>
14220 The function <function>xmlagg</function> is, unlike the other
14221 functions described here, an aggregate function. It concatenates the
14222 input values to the aggregate function call,
14223 much like <function>xmlconcat</function> does, except that concatenation
14224 occurs across rows rather than across expressions in a single row.
14225 See <xref linkend="functions-aggregate"/> for additional information
14226 about aggregate functions.
14227 </para>
14229 <para>
14230 Example:
14231 <screen><![CDATA[
14232 CREATE TABLE test (y int, x xml);
14233 INSERT INTO test VALUES (1, '<foo>abc</foo>');
14234 INSERT INTO test VALUES (2, '<bar/>');
14235 SELECT xmlagg(x) FROM test;
14236 xmlagg
14237 ----------------------
14238 <foo>abc</foo><bar/>
14239 ]]></screen>
14240 </para>
14242 <para>
14243 To determine the order of the concatenation, an <literal>ORDER BY</literal>
14244 clause may be added to the aggregate call as described in
14245 <xref linkend="syntax-aggregates"/>. For example:
14247 <screen><![CDATA[
14248 SELECT xmlagg(x ORDER BY y DESC) FROM test;
14249 xmlagg
14250 ----------------------
14251 <bar/><foo>abc</foo>
14252 ]]></screen>
14253 </para>
14255 <para>
14256 The following non-standard approach used to be recommended
14257 in previous versions, and may still be useful in specific
14258 cases:
14260 <screen><![CDATA[
14261 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
14262 xmlagg
14263 ----------------------
14264 <bar/><foo>abc</foo>
14265 ]]></screen>
14266 </para>
14267 </sect3>
14268 </sect2>
14270 <sect2 id="functions-xml-predicates">
14271 <title>XML Predicates</title>
14273 <para>
14274 The expressions described in this section check properties
14275 of <type>xml</type> values.
14276 </para>
14278 <sect3>
14279 <title><literal>IS DOCUMENT</literal></title>
14281 <indexterm>
14282 <primary>IS DOCUMENT</primary>
14283 </indexterm>
14285 <synopsis>
14286 <type>xml</type> <literal>IS DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14287 </synopsis>
14289 <para>
14290 The expression <literal>IS DOCUMENT</literal> returns true if the
14291 argument XML value is a proper XML document, false if it is not
14292 (that is, it is a content fragment), or null if the argument is
14293 null. See <xref linkend="datatype-xml"/> about the difference
14294 between documents and content fragments.
14295 </para>
14296 </sect3>
14298 <sect3>
14299 <title><literal>IS NOT DOCUMENT</literal></title>
14301 <indexterm>
14302 <primary>IS NOT DOCUMENT</primary>
14303 </indexterm>
14305 <synopsis>
14306 <type>xml</type> <literal>IS NOT DOCUMENT</literal> <returnvalue>boolean</returnvalue>
14307 </synopsis>
14309 <para>
14310 The expression <literal>IS NOT DOCUMENT</literal> returns false if the
14311 argument XML value is a proper XML document, true if it is not (that is,
14312 it is a content fragment), or null if the argument is null.
14313 </para>
14314 </sect3>
14316 <sect3 id="xml-exists">
14317 <title><literal>XMLEXISTS</literal></title>
14319 <indexterm>
14320 <primary>XMLEXISTS</primary>
14321 </indexterm>
14323 <synopsis>
14324 <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>
14325 </synopsis>
14327 <para>
14328 The function <function>xmlexists</function> evaluates an XPath 1.0
14329 expression (the first argument), with the passed XML value as its context
14330 item. The function returns false if the result of that evaluation
14331 yields an empty node-set, true if it yields any other value. The
14332 function returns null if any argument is null. A nonnull value
14333 passed as the context item must be an XML document, not a content
14334 fragment or any non-XML value.
14335 </para>
14337 <para>
14338 Example:
14339 <screen><![CDATA[
14340 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '<towns><town>Toronto</town><town>Ottawa</town></towns>');
14342 xmlexists
14343 ------------
14345 (1 row)
14346 ]]></screen>
14347 </para>
14349 <para>
14350 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
14351 are accepted in <productname>PostgreSQL</productname>, but are ignored,
14352 as discussed in <xref linkend="functions-xml-limits-postgresql"/>.
14353 </para>
14355 <para>
14356 In the SQL standard, the <function>xmlexists</function> function
14357 evaluates an expression in the XML Query language,
14358 but <productname>PostgreSQL</productname> allows only an XPath 1.0
14359 expression, as discussed in
14360 <xref linkend="functions-xml-limits-xpath1"/>.
14361 </para>
14362 </sect3>
14364 <sect3 id="xml-is-well-formed">
14365 <title><literal>xml_is_well_formed</literal></title>
14367 <indexterm>
14368 <primary>xml_is_well_formed</primary>
14369 </indexterm>
14371 <indexterm>
14372 <primary>xml_is_well_formed_document</primary>
14373 </indexterm>
14375 <indexterm>
14376 <primary>xml_is_well_formed_content</primary>
14377 </indexterm>
14379 <synopsis>
14380 <function>xml_is_well_formed</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14381 <function>xml_is_well_formed_document</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14382 <function>xml_is_well_formed_content</function> ( <type>text</type> ) <returnvalue>boolean</returnvalue>
14383 </synopsis>
14385 <para>
14386 These functions check whether a <type>text</type> string represents
14387 well-formed XML, returning a Boolean result.
14388 <function>xml_is_well_formed_document</function> checks for a well-formed
14389 document, while <function>xml_is_well_formed_content</function> checks
14390 for well-formed content. <function>xml_is_well_formed</function> does
14391 the former if the <xref linkend="guc-xmloption"/> configuration
14392 parameter is set to <literal>DOCUMENT</literal>, or the latter if it is set to
14393 <literal>CONTENT</literal>. This means that
14394 <function>xml_is_well_formed</function> is useful for seeing whether
14395 a simple cast to type <type>xml</type> will succeed, whereas the other two
14396 functions are useful for seeing whether the corresponding variants of
14397 <function>XMLPARSE</function> will succeed.
14398 </para>
14400 <para>
14401 Examples:
14403 <screen><![CDATA[
14404 SET xmloption TO DOCUMENT;
14405 SELECT xml_is_well_formed('<>');
14406 xml_is_well_formed
14407 --------------------
14409 (1 row)
14411 SELECT xml_is_well_formed('<abc/>');
14412 xml_is_well_formed
14413 --------------------
14415 (1 row)
14417 SET xmloption TO CONTENT;
14418 SELECT xml_is_well_formed('abc');
14419 xml_is_well_formed
14420 --------------------
14422 (1 row)
14424 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
14425 xml_is_well_formed_document
14426 -----------------------------
14428 (1 row)
14430 SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
14431 xml_is_well_formed_document
14432 -----------------------------
14434 (1 row)
14435 ]]></screen>
14437 The last example shows that the checks include whether
14438 namespaces are correctly matched.
14439 </para>
14440 </sect3>
14441 </sect2>
14443 <sect2 id="functions-xml-processing">
14444 <title>Processing XML</title>
14446 <para>
14447 To process values of data type <type>xml</type>, PostgreSQL offers
14448 the functions <function>xpath</function> and
14449 <function>xpath_exists</function>, which evaluate XPath 1.0
14450 expressions, and the <function>XMLTABLE</function>
14451 table function.
14452 </para>
14454 <sect3 id="functions-xml-processing-xpath">
14455 <title><literal>xpath</literal></title>
14457 <indexterm>
14458 <primary>XPath</primary>
14459 </indexterm>
14461 <synopsis>
14462 <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>
14463 </synopsis>
14465 <para>
14466 The function <function>xpath</function> evaluates the XPath 1.0
14467 expression <parameter>xpath</parameter> (given as text)
14468 against the XML value
14469 <parameter>xml</parameter>. It returns an array of XML values
14470 corresponding to the node-set produced by the XPath expression.
14471 If the XPath expression returns a scalar value rather than a node-set,
14472 a single-element array is returned.
14473 </para>
14475 <para>
14476 The second argument must be a well formed XML document. In particular,
14477 it must have a single root node element.
14478 </para>
14480 <para>
14481 The optional third argument of the function is an array of namespace
14482 mappings. This array should be a two-dimensional <type>text</type> array with
14483 the length of the second axis being equal to 2 (i.e., it should be an
14484 array of arrays, each of which consists of exactly 2 elements).
14485 The first element of each array entry is the namespace name (alias), the
14486 second the namespace URI. It is not required that aliases provided in
14487 this array be the same as those being used in the XML document itself (in
14488 other words, both in the XML document and in the <function>xpath</function>
14489 function context, aliases are <emphasis>local</emphasis>).
14490 </para>
14492 <para>
14493 Example:
14494 <screen><![CDATA[
14495 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
14496 ARRAY[ARRAY['my', 'http://example.com']]);
14498 xpath
14499 --------
14500 {test}
14501 (1 row)
14502 ]]></screen>
14503 </para>
14505 <para>
14506 To deal with default (anonymous) namespaces, do something like this:
14507 <screen><![CDATA[
14508 SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
14509 ARRAY[ARRAY['mydefns', 'http://example.com']]);
14511 xpath
14512 --------
14513 {test}
14514 (1 row)
14515 ]]></screen>
14516 </para>
14517 </sect3>
14519 <sect3 id="functions-xml-processing-xpath-exists">
14520 <title><literal>xpath_exists</literal></title>
14522 <indexterm>
14523 <primary>xpath_exists</primary>
14524 </indexterm>
14526 <synopsis>
14527 <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>
14528 </synopsis>
14530 <para>
14531 The function <function>xpath_exists</function> is a specialized form
14532 of the <function>xpath</function> function. Instead of returning the
14533 individual XML values that satisfy the XPath 1.0 expression, this function
14534 returns a Boolean indicating whether the query was satisfied or not
14535 (specifically, whether it produced any value other than an empty node-set).
14536 This function is equivalent to the <literal>XMLEXISTS</literal> predicate,
14537 except that it also offers support for a namespace mapping argument.
14538 </para>
14540 <para>
14541 Example:
14542 <screen><![CDATA[
14543 SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
14544 ARRAY[ARRAY['my', 'http://example.com']]);
14546 xpath_exists
14547 --------------
14549 (1 row)
14550 ]]></screen>
14551 </para>
14552 </sect3>
14554 <sect3 id="functions-xml-processing-xmltable">
14555 <title><literal>xmltable</literal></title>
14557 <indexterm>
14558 <primary>xmltable</primary>
14559 </indexterm>
14561 <indexterm zone="functions-xml-processing-xmltable">
14562 <primary>table function</primary>
14563 <secondary>XMLTABLE</secondary>
14564 </indexterm>
14566 <synopsis>
14567 <function>XMLTABLE</function> (
14568 <optional> <literal>XMLNAMESPACES</literal> ( <replaceable>namespace_uri</replaceable> <literal>AS</literal> <replaceable>namespace_name</replaceable> <optional>, ...</optional> ), </optional>
14569 <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>
14570 <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>
14571 | <literal>FOR ORDINALITY</literal> }
14572 <optional>, ...</optional>
14573 ) <returnvalue>setof record</returnvalue>
14574 </synopsis>
14576 <para>
14577 The <function>xmltable</function> expression produces a table based
14578 on an XML value, an XPath filter to extract rows, and a
14579 set of column definitions.
14580 Although it syntactically resembles a function, it can only appear
14581 as a table in a query's <literal>FROM</literal> clause.
14582 </para>
14584 <para>
14585 The optional <literal>XMLNAMESPACES</literal> clause gives a
14586 comma-separated list of namespace definitions, where
14587 each <replaceable>namespace_uri</replaceable> is a <type>text</type>
14588 expression and each <replaceable>namespace_name</replaceable> is a simple
14589 identifier. It specifies the XML namespaces used in the document and
14590 their aliases. A default namespace specification is not currently
14591 supported.
14592 </para>
14594 <para>
14595 The required <replaceable>row_expression</replaceable> argument is an
14596 XPath 1.0 expression (given as <type>text</type>) that is evaluated,
14597 passing the XML value <replaceable>document_expression</replaceable> as
14598 its context item, to obtain a set of XML nodes. These nodes are what
14599 <function>xmltable</function> transforms into output rows. No rows
14600 will be produced if the <replaceable>document_expression</replaceable>
14601 is null, nor if the <replaceable>row_expression</replaceable> produces
14602 an empty node-set or any value other than a node-set.
14603 </para>
14605 <para>
14606 <replaceable>document_expression</replaceable> provides the context
14607 item for the <replaceable>row_expression</replaceable>. It must be a
14608 well-formed XML document; fragments/forests are not accepted.
14609 The <literal>BY REF</literal> and <literal>BY VALUE</literal> clauses
14610 are accepted but ignored, as discussed in
14611 <xref linkend="functions-xml-limits-postgresql"/>.
14612 </para>
14614 <para>
14615 In the SQL standard, the <function>xmltable</function> function
14616 evaluates expressions in the XML Query language,
14617 but <productname>PostgreSQL</productname> allows only XPath 1.0
14618 expressions, as discussed in
14619 <xref linkend="functions-xml-limits-xpath1"/>.
14620 </para>
14622 <para>
14623 The required <literal>COLUMNS</literal> clause specifies the
14624 column(s) that will be produced in the output table.
14625 See the syntax summary above for the format.
14626 A name is required for each column, as is a data type
14627 (unless <literal>FOR ORDINALITY</literal> is specified, in which case
14628 type <type>integer</type> is implicit). The path, default and
14629 nullability clauses are optional.
14630 </para>
14632 <para>
14633 A column marked <literal>FOR ORDINALITY</literal> will be populated
14634 with row numbers, starting with 1, in the order of nodes retrieved from
14635 the <replaceable>row_expression</replaceable>'s result node-set.
14636 At most one column may be marked <literal>FOR ORDINALITY</literal>.
14637 </para>
14639 <note>
14640 <para>
14641 XPath 1.0 does not specify an order for nodes in a node-set, so code
14642 that relies on a particular order of the results will be
14643 implementation-dependent. Details can be found in
14644 <xref linkend="xml-xpath-1-specifics"/>.
14645 </para>
14646 </note>
14648 <para>
14649 The <replaceable>column_expression</replaceable> for a column is an
14650 XPath 1.0 expression that is evaluated for each row, with the current
14651 node from the <replaceable>row_expression</replaceable> result as its
14652 context item, to find the value of the column. If
14653 no <replaceable>column_expression</replaceable> is given, then the
14654 column name is used as an implicit path.
14655 </para>
14657 <para>
14658 If a column's XPath expression returns a non-XML value (which is limited
14659 to string, boolean, or double in XPath 1.0) and the column has a
14660 PostgreSQL type other than <type>xml</type>, the column will be set
14661 as if by assigning the value's string representation to the PostgreSQL
14662 type. (If the value is a boolean, its string representation is taken
14663 to be <literal>1</literal> or <literal>0</literal> if the output
14664 column's type category is numeric, otherwise <literal>true</literal> or
14665 <literal>false</literal>.)
14666 </para>
14668 <para>
14669 If a column's XPath expression returns a non-empty set of XML nodes
14670 and the column's PostgreSQL type is <type>xml</type>, the column will
14671 be assigned the expression result exactly, if it is of document or
14672 content form.
14673 <footnote>
14674 <para>
14675 A result containing more than one element node at the top level, or
14676 non-whitespace text outside of an element, is an example of content form.
14677 An XPath result can be of neither form, for example if it returns an
14678 attribute node selected from the element that contains it. Such a result
14679 will be put into content form with each such disallowed node replaced by
14680 its string value, as defined for the XPath 1.0
14681 <function>string</function> function.
14682 </para>
14683 </footnote>
14684 </para>
14686 <para>
14687 A non-XML result assigned to an <type>xml</type> output column produces
14688 content, a single text node with the string value of the result.
14689 An XML result assigned to a column of any other type may not have more than
14690 one node, or an error is raised. If there is exactly one node, the column
14691 will be set as if by assigning the node's string
14692 value (as defined for the XPath 1.0 <function>string</function> function)
14693 to the PostgreSQL type.
14694 </para>
14696 <para>
14697 The string value of an XML element is the concatenation, in document order,
14698 of all text nodes contained in that element and its descendants. The string
14699 value of an element with no descendant text nodes is an
14700 empty string (not <literal>NULL</literal>).
14701 Any <literal>xsi:nil</literal> attributes are ignored.
14702 Note that the whitespace-only <literal>text()</literal> node between two non-text
14703 elements is preserved, and that leading whitespace on a <literal>text()</literal>
14704 node is not flattened.
14705 The XPath 1.0 <function>string</function> function may be consulted for the
14706 rules defining the string value of other XML node types and non-XML values.
14707 </para>
14709 <para>
14710 The conversion rules presented here are not exactly those of the SQL
14711 standard, as discussed in <xref linkend="functions-xml-limits-casts"/>.
14712 </para>
14714 <para>
14715 If the path expression returns an empty node-set
14716 (typically, when it does not match)
14717 for a given row, the column will be set to <literal>NULL</literal>, unless
14718 a <replaceable>default_expression</replaceable> is specified; then the
14719 value resulting from evaluating that expression is used.
14720 </para>
14722 <para>
14723 A <replaceable>default_expression</replaceable>, rather than being
14724 evaluated immediately when <function>xmltable</function> is called,
14725 is evaluated each time a default is needed for the column.
14726 If the expression qualifies as stable or immutable, the repeat
14727 evaluation may be skipped.
14728 This means that you can usefully use volatile functions like
14729 <function>nextval</function> in
14730 <replaceable>default_expression</replaceable>.
14731 </para>
14733 <para>
14734 Columns may be marked <literal>NOT NULL</literal>. If the
14735 <replaceable>column_expression</replaceable> for a <literal>NOT
14736 NULL</literal> column does not match anything and there is
14737 no <literal>DEFAULT</literal> or
14738 the <replaceable>default_expression</replaceable> also evaluates to null,
14739 an error is reported.
14740 </para>
14742 <para>
14743 Examples:
14744 <screen><![CDATA[
14745 CREATE TABLE xmldata AS SELECT
14746 xml $$
14747 <ROWS>
14748 <ROW id="1">
14749 <COUNTRY_ID>AU</COUNTRY_ID>
14750 <COUNTRY_NAME>Australia</COUNTRY_NAME>
14751 </ROW>
14752 <ROW id="5">
14753 <COUNTRY_ID>JP</COUNTRY_ID>
14754 <COUNTRY_NAME>Japan</COUNTRY_NAME>
14755 <PREMIER_NAME>Shinzo Abe</PREMIER_NAME>
14756 <SIZE unit="sq_mi">145935</SIZE>
14757 </ROW>
14758 <ROW id="6">
14759 <COUNTRY_ID>SG</COUNTRY_ID>
14760 <COUNTRY_NAME>Singapore</COUNTRY_NAME>
14761 <SIZE unit="sq_km">697</SIZE>
14762 </ROW>
14763 </ROWS>
14764 $$ AS data;
14766 SELECT xmltable.*
14767 FROM xmldata,
14768 XMLTABLE('//ROWS/ROW'
14769 PASSING data
14770 COLUMNS id int PATH '@id',
14771 ordinality FOR ORDINALITY,
14772 "COUNTRY_NAME" text,
14773 country_id text PATH 'COUNTRY_ID',
14774 size_sq_km float PATH 'SIZE[@unit = "sq_km"]',
14775 size_other text PATH
14776 'concat(SIZE[@unit!="sq_km"], " ", SIZE[@unit!="sq_km"]/@unit)',
14777 premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified');
14779 id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
14780 ----+------------+--------------+------------+------------+--------------+---------------
14781 1 | 1 | Australia | AU | | | not specified
14782 5 | 2 | Japan | JP | | 145935 sq_mi | Shinzo Abe
14783 6 | 3 | Singapore | SG | 697 | | not specified
14784 ]]></screen>
14786 The following example shows concatenation of multiple text() nodes,
14787 usage of the column name as XPath filter, and the treatment of whitespace,
14788 XML comments and processing instructions:
14790 <screen><![CDATA[
14791 CREATE TABLE xmlelements AS SELECT
14792 xml $$
14793 <root>
14794 <element> Hello<!-- xyxxz -->2a2<?aaaaa?> <!--x--> bbb<x>xxx</x>CC </element>
14795 </root>
14796 $$ AS data;
14798 SELECT xmltable.*
14799 FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
14800 element
14801 -------------------------
14802 Hello2a2 bbbxxxCC
14803 ]]></screen>
14804 </para>
14806 <para>
14807 The following example illustrates how
14808 the <literal>XMLNAMESPACES</literal> clause can be used to specify
14809 a list of namespaces
14810 used in the XML document as well as in the XPath expressions:
14812 <screen><![CDATA[
14813 WITH xmldata(data) AS (VALUES ('
14814 <example xmlns="http://example.com/myns" xmlns:B="http://example.com/b">
14815 <item foo="1" B:bar="2"/>
14816 <item foo="3" B:bar="4"/>
14817 <item foo="4" B:bar="5"/>
14818 </example>'::xml)
14820 SELECT xmltable.*
14821 FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
14822 'http://example.com/b' AS "B"),
14823 '/x:example/x:item'
14824 PASSING (SELECT data FROM xmldata)
14825 COLUMNS foo int PATH '@foo',
14826 bar int PATH '@B:bar');
14827 foo | bar
14828 -----+-----
14829 1 | 2
14830 3 | 4
14831 4 | 5
14832 (3 rows)
14833 ]]></screen>
14834 </para>
14835 </sect3>
14836 </sect2>
14838 <sect2 id="functions-xml-mapping">
14839 <title>Mapping Tables to XML</title>
14841 <indexterm zone="functions-xml-mapping">
14842 <primary>XML export</primary>
14843 </indexterm>
14845 <para>
14846 The following functions map the contents of relational tables to
14847 XML values. They can be thought of as XML export functionality:
14848 <synopsis>
14849 <function>table_to_xml</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
14850 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14851 <function>query_to_xml</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
14852 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14853 <function>cursor_to_xml</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>count</parameter> <type>integer</type>, <parameter>nulls</parameter> <type>boolean</type>,
14854 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14855 </synopsis>
14856 </para>
14858 <para>
14859 <function>table_to_xml</function> maps the content of the named
14860 table, passed as parameter <parameter>table</parameter>. The
14861 <type>regclass</type> type accepts strings identifying tables using the
14862 usual notation, including optional schema qualification and
14863 double quotes (see <xref linkend="datatype-oid"/> for details).
14864 <function>query_to_xml</function> executes the
14865 query whose text is passed as parameter
14866 <parameter>query</parameter> and maps the result set.
14867 <function>cursor_to_xml</function> fetches the indicated number of
14868 rows from the cursor specified by the parameter
14869 <parameter>cursor</parameter>. This variant is recommended if
14870 large tables have to be mapped, because the result value is built
14871 up in memory by each function.
14872 </para>
14874 <para>
14875 If <parameter>tableforest</parameter> is false, then the resulting
14876 XML document looks like this:
14877 <screen><![CDATA[
14878 <tablename>
14879 <row>
14880 <columnname1>data</columnname1>
14881 <columnname2>data</columnname2>
14882 </row>
14884 <row>
14886 </row>
14889 </tablename>
14890 ]]></screen>
14892 If <parameter>tableforest</parameter> is true, the result is an
14893 XML content fragment that looks like this:
14894 <screen><![CDATA[
14895 <tablename>
14896 <columnname1>data</columnname1>
14897 <columnname2>data</columnname2>
14898 </tablename>
14900 <tablename>
14902 </tablename>
14905 ]]></screen>
14907 If no table name is available, that is, when mapping a query or a
14908 cursor, the string <literal>table</literal> is used in the first
14909 format, <literal>row</literal> in the second format.
14910 </para>
14912 <para>
14913 The choice between these formats is up to the user. The first
14914 format is a proper XML document, which will be important in many
14915 applications. The second format tends to be more useful in the
14916 <function>cursor_to_xml</function> function if the result values are to be
14917 reassembled into one document later on. The functions for
14918 producing XML content discussed above, in particular
14919 <function>xmlelement</function>, can be used to alter the results
14920 to taste.
14921 </para>
14923 <para>
14924 The data values are mapped in the same way as described for the
14925 function <function>xmlelement</function> above.
14926 </para>
14928 <para>
14929 The parameter <parameter>nulls</parameter> determines whether null
14930 values should be included in the output. If true, null values in
14931 columns are represented as:
14932 <screen><![CDATA[
14933 <columnname xsi:nil="true"/>
14934 ]]></screen>
14935 where <literal>xsi</literal> is the XML namespace prefix for XML
14936 Schema Instance. An appropriate namespace declaration will be
14937 added to the result value. If false, columns containing null
14938 values are simply omitted from the output.
14939 </para>
14941 <para>
14942 The parameter <parameter>targetns</parameter> specifies the
14943 desired XML namespace of the result. If no particular namespace
14944 is wanted, an empty string should be passed.
14945 </para>
14947 <para>
14948 The following functions return XML Schema documents describing the
14949 mappings performed by the corresponding functions above:
14950 <synopsis>
14951 <function>table_to_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
14952 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14953 <function>query_to_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
14954 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14955 <function>cursor_to_xmlschema</function> ( <parameter>cursor</parameter> <type>refcursor</type>, <parameter>nulls</parameter> <type>boolean</type>,
14956 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14957 </synopsis>
14958 It is essential that the same parameters are passed in order to
14959 obtain matching XML data mappings and XML Schema documents.
14960 </para>
14962 <para>
14963 The following functions produce XML data mappings and the
14964 corresponding XML Schema in one document (or forest), linked
14965 together. They can be useful where self-contained and
14966 self-describing results are wanted:
14967 <synopsis>
14968 <function>table_to_xml_and_xmlschema</function> ( <parameter>table</parameter> <type>regclass</type>, <parameter>nulls</parameter> <type>boolean</type>,
14969 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14970 <function>query_to_xml_and_xmlschema</function> ( <parameter>query</parameter> <type>text</type>, <parameter>nulls</parameter> <type>boolean</type>,
14971 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14972 </synopsis>
14973 </para>
14975 <para>
14976 In addition, the following functions are available to produce
14977 analogous mappings of entire schemas or the entire current
14978 database:
14979 <synopsis>
14980 <function>schema_to_xml</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
14981 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14982 <function>schema_to_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
14983 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14984 <function>schema_to_xml_and_xmlschema</function> ( <parameter>schema</parameter> <type>name</type>, <parameter>nulls</parameter> <type>boolean</type>,
14985 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14987 <function>database_to_xml</function> ( <parameter>nulls</parameter> <type>boolean</type>,
14988 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14989 <function>database_to_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
14990 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14991 <function>database_to_xml_and_xmlschema</function> ( <parameter>nulls</parameter> <type>boolean</type>,
14992 <parameter>tableforest</parameter> <type>boolean</type>, <parameter>targetns</parameter> <type>text</type> ) <returnvalue>xml</returnvalue>
14993 </synopsis>
14995 These functions ignore tables that are not readable by the current user.
14996 The database-wide functions additionally ignore schemas that the current
14997 user does not have <literal>USAGE</literal> (lookup) privilege for.
14998 </para>
15000 <para>
15001 Note that these potentially produce a lot of data, which needs to
15002 be built up in memory. When requesting content mappings of large
15003 schemas or databases, it might be worthwhile to consider mapping the
15004 tables separately instead, possibly even through a cursor.
15005 </para>
15007 <para>
15008 The result of a schema content mapping looks like this:
15010 <screen><![CDATA[
15011 <schemaname>
15013 table1-mapping
15015 table2-mapping
15019 </schemaname>]]></screen>
15021 where the format of a table mapping depends on the
15022 <parameter>tableforest</parameter> parameter as explained above.
15023 </para>
15025 <para>
15026 The result of a database content mapping looks like this:
15028 <screen><![CDATA[
15029 <dbname>
15031 <schema1name>
15033 </schema1name>
15035 <schema2name>
15037 </schema2name>
15041 </dbname>]]></screen>
15043 where the schema mapping is as above.
15044 </para>
15046 <para>
15047 As an example of using the output produced by these functions,
15048 <xref linkend="xslt-xml-html"/> shows an XSLT stylesheet that
15049 converts the output of
15050 <function>table_to_xml_and_xmlschema</function> to an HTML
15051 document containing a tabular rendition of the table data. In a
15052 similar manner, the results from these functions can be
15053 converted into other XML-based formats.
15054 </para>
15056 <example id="xslt-xml-html">
15057 <title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
15058 <programlisting><![CDATA[
15059 <?xml version="1.0"?>
15060 <xsl:stylesheet version="1.0"
15061 xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
15062 xmlns:xsd="http://www.w3.org/2001/XMLSchema"
15063 xmlns="http://www.w3.org/1999/xhtml"
15066 <xsl:output method="xml"
15067 doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
15068 doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
15069 indent="yes"/>
15071 <xsl:template match="/*">
15072 <xsl:variable name="schema" select="//xsd:schema"/>
15073 <xsl:variable name="tabletypename"
15074 select="$schema/xsd:element[@name=name(current())]/@type"/>
15075 <xsl:variable name="rowtypename"
15076 select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
15078 <html>
15079 <head>
15080 <title><xsl:value-of select="name(current())"/></title>
15081 </head>
15082 <body>
15083 <table>
15084 <tr>
15085 <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
15086 <th><xsl:value-of select="."/></th>
15087 </xsl:for-each>
15088 </tr>
15090 <xsl:for-each select="row">
15091 <tr>
15092 <xsl:for-each select="*">
15093 <td><xsl:value-of select="."/></td>
15094 </xsl:for-each>
15095 </tr>
15096 </xsl:for-each>
15097 </table>
15098 </body>
15099 </html>
15100 </xsl:template>
15102 </xsl:stylesheet>
15103 ]]></programlisting>
15104 </example>
15105 </sect2>
15106 </sect1>
15108 <sect1 id="functions-json">
15109 <title>JSON Functions and Operators</title>
15111 <indexterm zone="functions-json">
15112 <primary>JSON</primary>
15113 <secondary>functions and operators</secondary>
15114 </indexterm>
15116 <para>
15117 This section describes:
15119 <itemizedlist>
15120 <listitem>
15121 <para>
15122 functions and operators for processing and creating JSON data
15123 </para>
15124 </listitem>
15125 <listitem>
15126 <para>
15127 the SQL/JSON path language
15128 </para>
15129 </listitem>
15130 </itemizedlist>
15131 </para>
15133 <para>
15134 To learn more about the SQL/JSON standard, see
15135 <xref linkend="sqltr-19075-6"/>. For details on JSON types
15136 supported in <productname>PostgreSQL</productname>,
15137 see <xref linkend="datatype-json"/>.
15138 </para>
15140 <sect2 id="functions-json-processing">
15141 <title>Processing and Creating JSON Data</title>
15143 <para>
15144 <xref linkend="functions-json-op-table"/> shows the operators that
15145 are available for use with JSON data types (see <xref
15146 linkend="datatype-json"/>).
15147 In addition, the usual comparison operators shown in <xref
15148 linkend="functions-comparison-op-table"/> are available for
15149 <type>jsonb</type>, though not for <type>json</type>. The comparison
15150 operators follow the ordering rules for B-tree operations outlined in
15151 <xref linkend="json-indexing"/>.
15152 </para>
15154 <table id="functions-json-op-table">
15155 <title><type>json</type> and <type>jsonb</type> Operators</title>
15156 <tgroup cols="1">
15157 <thead>
15158 <row>
15159 <entry role="func_table_entry"><para role="func_signature">
15160 Operator
15161 </para>
15162 <para>
15163 Description
15164 </para>
15165 <para>
15166 Example(s)
15167 </para></entry>
15168 </row>
15169 </thead>
15171 <tbody>
15172 <row>
15173 <entry role="func_table_entry"><para role="func_signature">
15174 <type>json</type> <literal>-&gt;</literal> <type>integer</type>
15175 <returnvalue>json</returnvalue>
15176 </para>
15177 <para role="func_signature">
15178 <type>jsonb</type> <literal>-&gt;</literal> <type>integer</type>
15179 <returnvalue>jsonb</returnvalue>
15180 </para>
15181 <para>
15182 Extracts <parameter>n</parameter>'th element of JSON array
15183 (array elements are indexed from zero, but negative integers count
15184 from the end).
15185 </para>
15186 <para>
15187 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; 2</literal>
15188 <returnvalue>{"c":"baz"}</returnvalue>
15189 </para>
15190 <para>
15191 <literal>'[{"a":"foo"},{"b":"bar"},{"c":"baz"}]'::json -&gt; -3</literal>
15192 <returnvalue>{"a":"foo"}</returnvalue>
15193 </para></entry>
15194 </row>
15196 <row>
15197 <entry role="func_table_entry"><para role="func_signature">
15198 <type>json</type> <literal>-&gt;</literal> <type>text</type>
15199 <returnvalue>json</returnvalue>
15200 </para>
15201 <para role="func_signature">
15202 <type>jsonb</type> <literal>-&gt;</literal> <type>text</type>
15203 <returnvalue>jsonb</returnvalue>
15204 </para>
15205 <para>
15206 Extracts JSON object field with the given key.
15207 </para>
15208 <para>
15209 <literal>'{"a": {"b":"foo"}}'::json -&gt; 'a'</literal>
15210 <returnvalue>{"b":"foo"}</returnvalue>
15211 </para></entry>
15212 </row>
15214 <row>
15215 <entry role="func_table_entry"><para role="func_signature">
15216 <type>json</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15217 <returnvalue>text</returnvalue>
15218 </para>
15219 <para role="func_signature">
15220 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>integer</type>
15221 <returnvalue>text</returnvalue>
15222 </para>
15223 <para>
15224 Extracts <parameter>n</parameter>'th element of JSON array,
15225 as <type>text</type>.
15226 </para>
15227 <para>
15228 <literal>'[1,2,3]'::json -&gt;&gt; 2</literal>
15229 <returnvalue>3</returnvalue>
15230 </para></entry>
15231 </row>
15233 <row>
15234 <entry role="func_table_entry"><para role="func_signature">
15235 <type>json</type> <literal>-&gt;&gt;</literal> <type>text</type>
15236 <returnvalue>text</returnvalue>
15237 </para>
15238 <para role="func_signature">
15239 <type>jsonb</type> <literal>-&gt;&gt;</literal> <type>text</type>
15240 <returnvalue>text</returnvalue>
15241 </para>
15242 <para>
15243 Extracts JSON object field with the given key, as <type>text</type>.
15244 </para>
15245 <para>
15246 <literal>'{"a":1,"b":2}'::json -&gt;&gt; 'b'</literal>
15247 <returnvalue>2</returnvalue>
15248 </para></entry>
15249 </row>
15251 <row>
15252 <entry role="func_table_entry"><para role="func_signature">
15253 <type>json</type> <literal>#&gt;</literal> <type>text[]</type>
15254 <returnvalue>json</returnvalue>
15255 </para>
15256 <para role="func_signature">
15257 <type>jsonb</type> <literal>#&gt;</literal> <type>text[]</type>
15258 <returnvalue>jsonb</returnvalue>
15259 </para>
15260 <para>
15261 Extracts JSON sub-object at the specified path, where path elements
15262 can be either field keys or array indexes.
15263 </para>
15264 <para>
15265 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt; '{a,b,1}'</literal>
15266 <returnvalue>"bar"</returnvalue>
15267 </para></entry>
15268 </row>
15270 <row>
15271 <entry role="func_table_entry"><para role="func_signature">
15272 <type>json</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15273 <returnvalue>text</returnvalue>
15274 </para>
15275 <para role="func_signature">
15276 <type>jsonb</type> <literal>#&gt;&gt;</literal> <type>text[]</type>
15277 <returnvalue>text</returnvalue>
15278 </para>
15279 <para>
15280 Extracts JSON sub-object at the specified path as <type>text</type>.
15281 </para>
15282 <para>
15283 <literal>'{"a": {"b": ["foo","bar"]}}'::json #&gt;&gt; '{a,b,1}'</literal>
15284 <returnvalue>bar</returnvalue>
15285 </para></entry>
15286 </row>
15287 </tbody>
15288 </tgroup>
15289 </table>
15291 <note>
15292 <para>
15293 The field/element/path extraction operators return NULL, rather than
15294 failing, if the JSON input does not have the right structure to match
15295 the request; for example if no such key or array element exists.
15296 </para>
15297 </note>
15299 <para>
15300 Some further operators exist only for <type>jsonb</type>, as shown
15301 in <xref linkend="functions-jsonb-op-table"/>.
15302 <xref linkend="json-indexing"/>
15303 describes how these operators can be used to effectively search indexed
15304 <type>jsonb</type> data.
15305 </para>
15307 <table id="functions-jsonb-op-table">
15308 <title>Additional <type>jsonb</type> Operators</title>
15309 <tgroup cols="1">
15310 <thead>
15311 <row>
15312 <entry role="func_table_entry"><para role="func_signature">
15313 Operator
15314 </para>
15315 <para>
15316 Description
15317 </para>
15318 <para>
15319 Example(s)
15320 </para></entry>
15321 </row>
15322 </thead>
15324 <tbody>
15325 <row>
15326 <entry role="func_table_entry"><para role="func_signature">
15327 <type>jsonb</type> <literal>@&gt;</literal> <type>jsonb</type>
15328 <returnvalue>boolean</returnvalue>
15329 </para>
15330 <para>
15331 Does the first JSON value contain the second?
15332 (See <xref linkend="json-containment"/> for details about containment.)
15333 </para>
15334 <para>
15335 <literal>'{"a":1, "b":2}'::jsonb &#64;&gt; '{"b":2}'::jsonb</literal>
15336 <returnvalue>t</returnvalue>
15337 </para></entry>
15338 </row>
15340 <row>
15341 <entry role="func_table_entry"><para role="func_signature">
15342 <type>jsonb</type> <literal>&lt;@</literal> <type>jsonb</type>
15343 <returnvalue>boolean</returnvalue>
15344 </para>
15345 <para>
15346 Is the first JSON value contained in the second?
15347 </para>
15348 <para>
15349 <literal>'{"b":2}'::jsonb &lt;@ '{"a":1, "b":2}'::jsonb</literal>
15350 <returnvalue>t</returnvalue>
15351 </para></entry>
15352 </row>
15354 <row>
15355 <entry role="func_table_entry"><para role="func_signature">
15356 <type>jsonb</type> <literal>?</literal> <type>text</type>
15357 <returnvalue>boolean</returnvalue>
15358 </para>
15359 <para>
15360 Does the text string exist as a top-level key or array element within
15361 the JSON value?
15362 </para>
15363 <para>
15364 <literal>'{"a":1, "b":2}'::jsonb ? 'b'</literal>
15365 <returnvalue>t</returnvalue>
15366 </para>
15367 <para>
15368 <literal>'["a", "b", "c"]'::jsonb ? 'b'</literal>
15369 <returnvalue>t</returnvalue>
15370 </para></entry>
15371 </row>
15373 <row>
15374 <entry role="func_table_entry"><para role="func_signature">
15375 <type>jsonb</type> <literal>?|</literal> <type>text[]</type>
15376 <returnvalue>boolean</returnvalue>
15377 </para>
15378 <para>
15379 Do any of the strings in the text array exist as top-level keys or
15380 array elements?
15381 </para>
15382 <para>
15383 <literal>'{"a":1, "b":2, "c":3}'::jsonb ?| array['b', 'd']</literal>
15384 <returnvalue>t</returnvalue>
15385 </para></entry>
15386 </row>
15388 <row>
15389 <entry role="func_table_entry"><para role="func_signature">
15390 <type>jsonb</type> <literal>?&amp;</literal> <type>text[]</type>
15391 <returnvalue>boolean</returnvalue>
15392 </para>
15393 <para>
15394 Do all of the strings in the text array exist as top-level keys or
15395 array elements?
15396 </para>
15397 <para>
15398 <literal>'["a", "b", "c"]'::jsonb ?&amp; array['a', 'b']</literal>
15399 <returnvalue>t</returnvalue>
15400 </para></entry>
15401 </row>
15403 <row>
15404 <entry role="func_table_entry"><para role="func_signature">
15405 <type>jsonb</type> <literal>||</literal> <type>jsonb</type>
15406 <returnvalue>jsonb</returnvalue>
15407 </para>
15408 <para>
15409 Concatenates two <type>jsonb</type> values.
15410 Concatenating two arrays generates an array containing all the
15411 elements of each input. Concatenating two objects generates an
15412 object containing the union of their
15413 keys, taking the second object's value when there are duplicate keys.
15414 All other cases are treated by converting a non-array input into a
15415 single-element array, and then proceeding as for two arrays.
15416 Does not operate recursively: only the top-level array or object
15417 structure is merged.
15418 </para>
15419 <para>
15420 <literal>'["a", "b"]'::jsonb || '["a", "d"]'::jsonb</literal>
15421 <returnvalue>["a", "b", "a", "d"]</returnvalue>
15422 </para>
15423 <para>
15424 <literal>'{"a": "b"}'::jsonb || '{"c": "d"}'::jsonb</literal>
15425 <returnvalue>{"a": "b", "c": "d"}</returnvalue>
15426 </para>
15427 <para>
15428 <literal>'[1, 2]'::jsonb || '3'::jsonb</literal>
15429 <returnvalue>[1, 2, 3]</returnvalue>
15430 </para>
15431 <para>
15432 <literal>'{"a": "b"}'::jsonb || '42'::jsonb</literal>
15433 <returnvalue>[{"a": "b"}, 42]</returnvalue>
15434 </para>
15435 <para>
15436 To append an array to another array as a single entry, wrap it
15437 in an additional layer of array, for example:
15438 </para>
15439 <para>
15440 <literal>'[1, 2]'::jsonb || jsonb_build_array('[3, 4]'::jsonb)</literal>
15441 <returnvalue>[1, 2, [3, 4]]</returnvalue>
15442 </para></entry>
15443 </row>
15445 <row>
15446 <entry role="func_table_entry"><para role="func_signature">
15447 <type>jsonb</type> <literal>-</literal> <type>text</type>
15448 <returnvalue>jsonb</returnvalue>
15449 </para>
15450 <para>
15451 Deletes a key (and its value) from a JSON object, or matching string
15452 value(s) from a JSON array.
15453 </para>
15454 <para>
15455 <literal>'{"a": "b", "c": "d"}'::jsonb - 'a'</literal>
15456 <returnvalue>{"c": "d"}</returnvalue>
15457 </para>
15458 <para>
15459 <literal>'["a", "b", "c", "b"]'::jsonb - 'b'</literal>
15460 <returnvalue>["a", "c"]</returnvalue>
15461 </para></entry>
15462 </row>
15464 <row>
15465 <entry role="func_table_entry"><para role="func_signature">
15466 <type>jsonb</type> <literal>-</literal> <type>text[]</type>
15467 <returnvalue>jsonb</returnvalue>
15468 </para>
15469 <para>
15470 Deletes all matching keys or array elements from the left operand.
15471 </para>
15472 <para>
15473 <literal>'{"a": "b", "c": "d"}'::jsonb - '{a,c}'::text[]</literal>
15474 <returnvalue>{}</returnvalue>
15475 </para></entry>
15476 </row>
15478 <row>
15479 <entry role="func_table_entry"><para role="func_signature">
15480 <type>jsonb</type> <literal>-</literal> <type>integer</type>
15481 <returnvalue>jsonb</returnvalue>
15482 </para>
15483 <para>
15484 Deletes the array element with specified index (negative
15485 integers count from the end). Throws an error if JSON value
15486 is not an array.
15487 </para>
15488 <para>
15489 <literal>'["a", "b"]'::jsonb - 1 </literal>
15490 <returnvalue>["a"]</returnvalue>
15491 </para></entry>
15492 </row>
15494 <row>
15495 <entry role="func_table_entry"><para role="func_signature">
15496 <type>jsonb</type> <literal>#-</literal> <type>text[]</type>
15497 <returnvalue>jsonb</returnvalue>
15498 </para>
15499 <para>
15500 Deletes the field or array element at the specified path, where path
15501 elements can be either field keys or array indexes.
15502 </para>
15503 <para>
15504 <literal>'["a", {"b":1}]'::jsonb #- '{1,b}'</literal>
15505 <returnvalue>["a", {}]</returnvalue>
15506 </para></entry>
15507 </row>
15509 <row>
15510 <entry role="func_table_entry"><para role="func_signature">
15511 <type>jsonb</type> <literal>@?</literal> <type>jsonpath</type>
15512 <returnvalue>boolean</returnvalue>
15513 </para>
15514 <para>
15515 Does JSON path return any item for the specified JSON value?
15516 </para>
15517 <para>
15518 <literal>'{"a":[1,2,3,4,5]}'::jsonb @? '$.a[*] ? (@ > 2)'</literal>
15519 <returnvalue>t</returnvalue>
15520 </para></entry>
15521 </row>
15523 <row>
15524 <entry role="func_table_entry"><para role="func_signature">
15525 <type>jsonb</type> <literal>@@</literal> <type>jsonpath</type>
15526 <returnvalue>boolean</returnvalue>
15527 </para>
15528 <para>
15529 Returns the result of a JSON path predicate check for the
15530 specified JSON value. Only the first item of the result is taken into
15531 account. If the result is not Boolean, then <literal>NULL</literal>
15532 is returned.
15533 </para>
15534 <para>
15535 <literal>'{"a":[1,2,3,4,5]}'::jsonb @@ '$.a[*] > 2'</literal>
15536 <returnvalue>t</returnvalue>
15537 </para></entry>
15538 </row>
15539 </tbody>
15540 </tgroup>
15541 </table>
15543 <note>
15544 <para>
15545 The <type>jsonpath</type> operators <literal>@?</literal>
15546 and <literal>@@</literal> suppress the following errors: missing object
15547 field or array element, unexpected JSON item type, datetime and numeric
15548 errors. The <type>jsonpath</type>-related functions described below can
15549 also be told to suppress these types of errors. This behavior might be
15550 helpful when searching JSON document collections of varying structure.
15551 </para>
15552 </note>
15554 <para>
15555 <xref linkend="functions-json-creation-table"/> shows the functions that are
15556 available for constructing <type>json</type> and <type>jsonb</type> values.
15557 </para>
15559 <table id="functions-json-creation-table">
15560 <title>JSON Creation Functions</title>
15561 <tgroup cols="1">
15562 <thead>
15563 <row>
15564 <entry role="func_table_entry"><para role="func_signature">
15565 Function
15566 </para>
15567 <para>
15568 Description
15569 </para>
15570 <para>
15571 Example(s)
15572 </para></entry>
15573 </row>
15574 </thead>
15576 <tbody>
15577 <row>
15578 <entry role="func_table_entry"><para role="func_signature">
15579 <indexterm>
15580 <primary>to_json</primary>
15581 </indexterm>
15582 <function>to_json</function> ( <type>anyelement</type> )
15583 <returnvalue>json</returnvalue>
15584 </para>
15585 <para role="func_signature">
15586 <indexterm>
15587 <primary>to_jsonb</primary>
15588 </indexterm>
15589 <function>to_jsonb</function> ( <type>anyelement</type> )
15590 <returnvalue>jsonb</returnvalue>
15591 </para>
15592 <para>
15593 Converts any SQL value to <type>json</type> or <type>jsonb</type>.
15594 Arrays and composites are converted recursively to arrays and
15595 objects (multidimensional arrays become arrays of arrays in JSON).
15596 Otherwise, if there is a cast from the SQL data type
15597 to <type>json</type>, the cast function will be used to perform the
15598 conversion;<footnote>
15599 <para>
15600 For example, the <xref linkend="hstore"/> extension has a cast
15601 from <type>hstore</type> to <type>json</type>, so that
15602 <type>hstore</type> values converted via the JSON creation functions
15603 will be represented as JSON objects, not as primitive string values.
15604 </para>
15605 </footnote>
15606 otherwise, a scalar JSON value is produced. For any scalar other than
15607 a number, a Boolean, or a null value, the text representation will be
15608 used, with escaping as necessary to make it a valid JSON string value.
15609 </para>
15610 <para>
15611 <literal>to_json('Fred said "Hi."'::text)</literal>
15612 <returnvalue>"Fred said \"Hi.\""</returnvalue>
15613 </para>
15614 <para>
15615 <literal>to_jsonb(row(42, 'Fred said "Hi."'::text))</literal>
15616 <returnvalue>{"f1": 42, "f2": "Fred said \"Hi.\""}</returnvalue>
15617 </para></entry>
15618 </row>
15620 <row>
15621 <entry role="func_table_entry"><para role="func_signature">
15622 <indexterm>
15623 <primary>array_to_json</primary>
15624 </indexterm>
15625 <function>array_to_json</function> ( <type>anyarray</type> <optional>, <type>boolean</type> </optional> )
15626 <returnvalue>json</returnvalue>
15627 </para>
15628 <para>
15629 Converts an SQL array to a JSON array. The behavior is the same
15630 as <function>to_json</function> except that line feeds will be added
15631 between top-level array elements if the optional boolean parameter is
15632 true.
15633 </para>
15634 <para>
15635 <literal>array_to_json('{{1,5},{99,100}}'::int[])</literal>
15636 <returnvalue>[[1,5],[99,100]]</returnvalue>
15637 </para></entry>
15638 </row>
15640 <row>
15641 <entry role="func_table_entry"><para role="func_signature">
15642 <indexterm>
15643 <primary>row_to_json</primary>
15644 </indexterm>
15645 <function>row_to_json</function> ( <type>record</type> <optional>, <type>boolean</type> </optional> )
15646 <returnvalue>json</returnvalue>
15647 </para>
15648 <para>
15649 Converts an SQL composite value to a JSON object. The behavior is the
15650 same as <function>to_json</function> except that line feeds will be
15651 added between top-level elements if the optional boolean parameter is
15652 true.
15653 </para>
15654 <para>
15655 <literal>row_to_json(row(1,'foo'))</literal>
15656 <returnvalue>{"f1":1,"f2":"foo"}</returnvalue>
15657 </para></entry>
15658 </row>
15660 <row>
15661 <entry role="func_table_entry"><para role="func_signature">
15662 <indexterm>
15663 <primary>json_build_array</primary>
15664 </indexterm>
15665 <function>json_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15666 <returnvalue>json</returnvalue>
15667 </para>
15668 <para role="func_signature">
15669 <indexterm>
15670 <primary>jsonb_build_array</primary>
15671 </indexterm>
15672 <function>jsonb_build_array</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15673 <returnvalue>jsonb</returnvalue>
15674 </para>
15675 <para>
15676 Builds a possibly-heterogeneously-typed JSON array out of a variadic
15677 argument list. Each argument is converted as
15678 per <function>to_json</function> or <function>to_jsonb</function>.
15679 </para>
15680 <para>
15681 <literal>json_build_array(1, 2, 'foo', 4, 5)</literal>
15682 <returnvalue>[1, 2, "foo", 4, 5]</returnvalue>
15683 </para></entry>
15684 </row>
15686 <row>
15687 <entry role="func_table_entry"><para role="func_signature">
15688 <indexterm>
15689 <primary>json_build_object</primary>
15690 </indexterm>
15691 <function>json_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15692 <returnvalue>json</returnvalue>
15693 </para>
15694 <para role="func_signature">
15695 <indexterm>
15696 <primary>jsonb_build_object</primary>
15697 </indexterm>
15698 <function>jsonb_build_object</function> ( <literal>VARIADIC</literal> <type>"any"</type> )
15699 <returnvalue>jsonb</returnvalue>
15700 </para>
15701 <para>
15702 Builds a JSON object out of a variadic argument list. By convention,
15703 the argument list consists of alternating keys and values. Key
15704 arguments are coerced to text; value arguments are converted as
15705 per <function>to_json</function> or <function>to_jsonb</function>.
15706 </para>
15707 <para>
15708 <literal>json_build_object('foo', 1, 2, row(3,'bar'))</literal>
15709 <returnvalue>{"foo" : 1, "2" : {"f1":3,"f2":"bar"}}</returnvalue>
15710 </para></entry>
15711 </row>
15713 <row>
15714 <entry role="func_table_entry"><para role="func_signature">
15715 <indexterm>
15716 <primary>json_object</primary>
15717 </indexterm>
15718 <function>json_object</function> ( <type>text[]</type> )
15719 <returnvalue>json</returnvalue>
15720 </para>
15721 <para role="func_signature">
15722 <indexterm>
15723 <primary>jsonb_object</primary>
15724 </indexterm>
15725 <function>jsonb_object</function> ( <type>text[]</type> )
15726 <returnvalue>jsonb</returnvalue>
15727 </para>
15728 <para>
15729 Builds a JSON object out of a text array. The array must have either
15730 exactly one dimension with an even number of members, in which case
15731 they are taken as alternating key/value pairs, or two dimensions
15732 such that each inner array has exactly two elements, which
15733 are taken as a key/value pair. All values are converted to JSON
15734 strings.
15735 </para>
15736 <para>
15737 <literal>json_object('{a, 1, b, "def", c, 3.5}')</literal>
15738 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
15739 </para>
15740 <para><literal>json_object('{{a, 1}, {b, "def"}, {c, 3.5}}')</literal>
15741 <returnvalue>{"a" : "1", "b" : "def", "c" : "3.5"}</returnvalue>
15742 </para></entry>
15743 </row>
15745 <row>
15746 <entry role="func_table_entry"><para role="func_signature">
15747 <function>json_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
15748 <returnvalue>json</returnvalue>
15749 </para>
15750 <para role="func_signature">
15751 <function>jsonb_object</function> ( <parameter>keys</parameter> <type>text[]</type>, <parameter>values</parameter> <type>text[]</type> )
15752 <returnvalue>jsonb</returnvalue>
15753 </para>
15754 <para>
15755 This form of <function>json_object</function> takes keys and values
15756 pairwise from separate text arrays. Otherwise it is identical to
15757 the one-argument form.
15758 </para>
15759 <para>
15760 <literal>json_object('{a,b}', '{1,2}')</literal>
15761 <returnvalue>{"a": "1", "b": "2"}</returnvalue>
15762 </para></entry>
15763 </row>
15764 </tbody>
15765 </tgroup>
15766 </table>
15768 <para>
15769 <xref linkend="functions-json-processing-table"/> shows the functions that
15770 are available for processing <type>json</type> and <type>jsonb</type> values.
15771 </para>
15773 <table id="functions-json-processing-table">
15774 <title>JSON Processing Functions</title>
15775 <tgroup cols="1">
15776 <thead>
15777 <row>
15778 <entry role="func_table_entry"><para role="func_signature">
15779 Function
15780 </para>
15781 <para>
15782 Description
15783 </para>
15784 <para>
15785 Example(s)
15786 </para></entry>
15787 </row>
15788 </thead>
15790 <tbody>
15791 <row>
15792 <entry role="func_table_entry"><para role="func_signature">
15793 <indexterm>
15794 <primary>json_array_elements</primary>
15795 </indexterm>
15796 <function>json_array_elements</function> ( <type>json</type> )
15797 <returnvalue>setof json</returnvalue>
15798 </para>
15799 <para role="func_signature">
15800 <indexterm>
15801 <primary>jsonb_array_elements</primary>
15802 </indexterm>
15803 <function>jsonb_array_elements</function> ( <type>jsonb</type> )
15804 <returnvalue>setof jsonb</returnvalue>
15805 </para>
15806 <para>
15807 Expands the top-level JSON array into a set of JSON values.
15808 </para>
15809 <para>
15810 <literal>select * from json_array_elements('[1,true, [2,false]]')</literal>
15811 <returnvalue></returnvalue>
15812 <programlisting>
15813 value
15814 -----------
15816 true
15817 [2,false]
15818 </programlisting>
15819 </para></entry>
15820 </row>
15822 <row>
15823 <entry role="func_table_entry"><para role="func_signature">
15824 <indexterm>
15825 <primary>json_array_elements_text</primary>
15826 </indexterm>
15827 <function>json_array_elements_text</function> ( <type>json</type> )
15828 <returnvalue>setof text</returnvalue>
15829 </para>
15830 <para role="func_signature">
15831 <indexterm>
15832 <primary>jsonb_array_elements_text</primary>
15833 </indexterm>
15834 <function>jsonb_array_elements_text</function> ( <type>jsonb</type> )
15835 <returnvalue>setof text</returnvalue>
15836 </para>
15837 <para>
15838 Expands the top-level JSON array into a set of <type>text</type> values.
15839 </para>
15840 <para>
15841 <literal>select * from json_array_elements_text('["foo", "bar"]')</literal>
15842 <returnvalue></returnvalue>
15843 <programlisting>
15844 value
15845 -----------
15848 </programlisting>
15849 </para></entry>
15850 </row>
15852 <row>
15853 <entry role="func_table_entry"><para role="func_signature">
15854 <indexterm>
15855 <primary>json_array_length</primary>
15856 </indexterm>
15857 <function>json_array_length</function> ( <type>json</type> )
15858 <returnvalue>integer</returnvalue>
15859 </para>
15860 <para role="func_signature">
15861 <indexterm>
15862 <primary>jsonb_array_length</primary>
15863 </indexterm>
15864 <function>jsonb_array_length</function> ( <type>jsonb</type> )
15865 <returnvalue>integer</returnvalue>
15866 </para>
15867 <para>
15868 Returns the number of elements in the top-level JSON array.
15869 </para>
15870 <para>
15871 <literal>json_array_length('[1,2,3,{"f1":1,"f2":[5,6]},4]')</literal>
15872 <returnvalue>5</returnvalue>
15873 </para>
15874 <para>
15875 <literal>jsonb_array_length('[]')</literal>
15876 <returnvalue>0</returnvalue>
15877 </para></entry>
15878 </row>
15880 <row>
15881 <entry role="func_table_entry"><para role="func_signature">
15882 <indexterm>
15883 <primary>json_each</primary>
15884 </indexterm>
15885 <function>json_each</function> ( <type>json</type> )
15886 <returnvalue>setof record</returnvalue>
15887 ( <parameter>key</parameter> <type>text</type>,
15888 <parameter>value</parameter> <type>json</type> )
15889 </para>
15890 <para role="func_signature">
15891 <indexterm>
15892 <primary>jsonb_each</primary>
15893 </indexterm>
15894 <function>jsonb_each</function> ( <type>jsonb</type> )
15895 <returnvalue>setof record</returnvalue>
15896 ( <parameter>key</parameter> <type>text</type>,
15897 <parameter>value</parameter> <type>jsonb</type> )
15898 </para>
15899 <para>
15900 Expands the top-level JSON object into a set of key/value pairs.
15901 </para>
15902 <para>
15903 <literal>select * from json_each('{"a":"foo", "b":"bar"}')</literal>
15904 <returnvalue></returnvalue>
15905 <programlisting>
15906 key | value
15907 -----+-------
15908 a | "foo"
15909 b | "bar"
15910 </programlisting>
15911 </para></entry>
15912 </row>
15914 <row>
15915 <entry role="func_table_entry"><para role="func_signature">
15916 <indexterm>
15917 <primary>json_each_text</primary>
15918 </indexterm>
15919 <function>json_each_text</function> ( <type>json</type> )
15920 <returnvalue>setof record</returnvalue>
15921 ( <parameter>key</parameter> <type>text</type>,
15922 <parameter>value</parameter> <type>text</type> )
15923 </para>
15924 <para role="func_signature">
15925 <indexterm>
15926 <primary>jsonb_each_text</primary>
15927 </indexterm>
15928 <function>jsonb_each_text</function> ( <type>jsonb</type> )
15929 <returnvalue>setof record</returnvalue>
15930 ( <parameter>key</parameter> <type>text</type>,
15931 <parameter>value</parameter> <type>text</type> )
15932 </para>
15933 <para>
15934 Expands the top-level JSON object into a set of key/value pairs.
15935 The returned <parameter>value</parameter>s will be of
15936 type <type>text</type>.
15937 </para>
15938 <para>
15939 <literal>select * from json_each_text('{"a":"foo", "b":"bar"}')</literal>
15940 <returnvalue></returnvalue>
15941 <programlisting>
15942 key | value
15943 -----+-------
15944 a | foo
15945 b | bar
15946 </programlisting>
15947 </para></entry>
15948 </row>
15950 <row>
15951 <entry role="func_table_entry"><para role="func_signature">
15952 <indexterm>
15953 <primary>json_extract_path</primary>
15954 </indexterm>
15955 <function>json_extract_path</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
15956 <returnvalue>json</returnvalue>
15957 </para>
15958 <para role="func_signature">
15959 <indexterm>
15960 <primary>jsonb_extract_path</primary>
15961 </indexterm>
15962 <function>jsonb_extract_path</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
15963 <returnvalue>jsonb</returnvalue>
15964 </para>
15965 <para>
15966 Extracts JSON sub-object at the specified path.
15967 (This is functionally equivalent to the <literal>#&gt;</literal>
15968 operator, but writing the path out as a variadic list can be more
15969 convenient in some cases.)
15970 </para>
15971 <para>
15972 <literal>json_extract_path('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
15973 <returnvalue>"foo"</returnvalue>
15974 </para></entry>
15975 </row>
15977 <row>
15978 <entry role="func_table_entry"><para role="func_signature">
15979 <indexterm>
15980 <primary>json_extract_path_text</primary>
15981 </indexterm>
15982 <function>json_extract_path_text</function> ( <parameter>from_json</parameter> <type>json</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
15983 <returnvalue>text</returnvalue>
15984 </para>
15985 <para role="func_signature">
15986 <indexterm>
15987 <primary>jsonb_extract_path_text</primary>
15988 </indexterm>
15989 <function>jsonb_extract_path_text</function> ( <parameter>from_json</parameter> <type>jsonb</type>, <literal>VARIADIC</literal> <parameter>path_elems</parameter> <type>text[]</type> )
15990 <returnvalue>text</returnvalue>
15991 </para>
15992 <para>
15993 Extracts JSON sub-object at the specified path as <type>text</type>.
15994 (This is functionally equivalent to the <literal>#&gt;&gt;</literal>
15995 operator.)
15996 </para>
15997 <para>
15998 <literal>json_extract_path_text('{"f2":{"f3":1},"f4":{"f5":99,"f6":"foo"}}', 'f4', 'f6')</literal>
15999 <returnvalue>foo</returnvalue>
16000 </para></entry>
16001 </row>
16003 <row>
16004 <entry role="func_table_entry"><para role="func_signature">
16005 <indexterm>
16006 <primary>json_object_keys</primary>
16007 </indexterm>
16008 <function>json_object_keys</function> ( <type>json</type> )
16009 <returnvalue>setof text</returnvalue>
16010 </para>
16011 <para role="func_signature">
16012 <indexterm>
16013 <primary>jsonb_object_keys</primary>
16014 </indexterm>
16015 <function>jsonb_object_keys</function> ( <type>jsonb</type> )
16016 <returnvalue>setof text</returnvalue>
16017 </para>
16018 <para>
16019 Returns the set of keys in the top-level JSON object.
16020 </para>
16021 <para>
16022 <literal>select * from json_object_keys('{"f1":"abc","f2":{"f3":"a", "f4":"b"}}')</literal>
16023 <returnvalue></returnvalue>
16024 <programlisting>
16025 json_object_keys
16026 ------------------
16029 </programlisting>
16030 </para></entry>
16031 </row>
16033 <row>
16034 <entry role="func_table_entry"><para role="func_signature">
16035 <indexterm>
16036 <primary>json_populate_record</primary>
16037 </indexterm>
16038 <function>json_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16039 <returnvalue>anyelement</returnvalue>
16040 </para>
16041 <para role="func_signature">
16042 <indexterm>
16043 <primary>jsonb_populate_record</primary>
16044 </indexterm>
16045 <function>jsonb_populate_record</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16046 <returnvalue>anyelement</returnvalue>
16047 </para>
16048 <para>
16049 Expands the top-level JSON object to a row having the composite type
16050 of the <parameter>base</parameter> argument. The JSON object
16051 is scanned for fields whose names match column names of the output row
16052 type, and their values are inserted into those columns of the output.
16053 (Fields that do not correspond to any output column name are ignored.)
16054 In typical use, the value of <parameter>base</parameter> is just
16055 <literal>NULL</literal>, which means that any output columns that do
16056 not match any object field will be filled with nulls. However,
16057 if <parameter>base</parameter> isn't <literal>NULL</literal> then
16058 the values it contains will be used for unmatched columns.
16059 </para>
16060 <para>
16061 To convert a JSON value to the SQL type of an output column, the
16062 following rules are applied in sequence:
16063 <itemizedlist spacing="compact">
16064 <listitem>
16065 <para>
16066 A JSON null value is converted to an SQL null in all cases.
16067 </para>
16068 </listitem>
16069 <listitem>
16070 <para>
16071 If the output column is of type <type>json</type>
16072 or <type>jsonb</type>, the JSON value is just reproduced exactly.
16073 </para>
16074 </listitem>
16075 <listitem>
16076 <para>
16077 If the output column is a composite (row) type, and the JSON value
16078 is a JSON object, the fields of the object are converted to columns
16079 of the output row type by recursive application of these rules.
16080 </para>
16081 </listitem>
16082 <listitem>
16083 <para>
16084 Likewise, if the output column is an array type and the JSON value
16085 is a JSON array, the elements of the JSON array are converted to
16086 elements of the output array by recursive application of these
16087 rules.
16088 </para>
16089 </listitem>
16090 <listitem>
16091 <para>
16092 Otherwise, if the JSON value is a string, the contents of the
16093 string are fed to the input conversion function for the column's
16094 data type.
16095 </para>
16096 </listitem>
16097 <listitem>
16098 <para>
16099 Otherwise, the ordinary text representation of the JSON value is
16100 fed to the input conversion function for the column's data type.
16101 </para>
16102 </listitem>
16103 </itemizedlist>
16104 </para>
16105 <para>
16106 While the example below uses a constant JSON value, typical use would
16107 be to reference a <type>json</type> or <type>jsonb</type> column
16108 laterally from another table in the query's <literal>FROM</literal>
16109 clause. Writing <function>json_populate_record</function> in
16110 the <literal>FROM</literal> clause is good practice, since all of the
16111 extracted columns are available for use without duplicate function
16112 calls.
16113 </para>
16114 <para>
16115 <literal>create type subrowtype as (d int, e text);</literal>
16116 <literal>create type myrowtype as (a int, b text[], c subrowtype);</literal>
16117 </para>
16118 <para>
16119 <literal>select * from json_populate_record(null::myrowtype,
16120 '{"a": 1, "b": ["2", "a b"], "c": {"d": 4, "e": "a b c"}, "x": "foo"}')</literal>
16121 <returnvalue></returnvalue>
16122 <programlisting>
16123 a | b | c
16124 ---+-----------+-------------
16125 1 | {2,"a b"} | (4,"a b c")
16126 </programlisting>
16127 </para></entry>
16128 </row>
16130 <row>
16131 <entry role="func_table_entry"><para role="func_signature">
16132 <indexterm>
16133 <primary>json_populate_recordset</primary>
16134 </indexterm>
16135 <function>json_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>json</type> )
16136 <returnvalue>setof anyelement</returnvalue>
16137 </para>
16138 <para role="func_signature">
16139 <indexterm>
16140 <primary>jsonb_populate_recordset</primary>
16141 </indexterm>
16142 <function>jsonb_populate_recordset</function> ( <parameter>base</parameter> <type>anyelement</type>, <parameter>from_json</parameter> <type>jsonb</type> )
16143 <returnvalue>setof anyelement</returnvalue>
16144 </para>
16145 <para>
16146 Expands the top-level JSON array of objects to a set of rows having
16147 the composite type of the <parameter>base</parameter> argument.
16148 Each element of the JSON array is processed as described above
16149 for <function>json[b]_populate_record</function>.
16150 </para>
16151 <para>
16152 <literal>create type twoints as (a int, b int);</literal>
16153 </para>
16154 <para>
16155 <literal>select * from json_populate_recordset(null::twoints, '[{"a":1,"b":2}, {"a":3,"b":4}]')</literal>
16156 <returnvalue></returnvalue>
16157 <programlisting>
16158 a | b
16159 ---+---
16160 1 | 2
16161 3 | 4
16162 </programlisting>
16163 </para></entry>
16164 </row>
16166 <row>
16167 <entry role="func_table_entry"><para role="func_signature">
16168 <indexterm>
16169 <primary>json_to_record</primary>
16170 </indexterm>
16171 <function>json_to_record</function> ( <type>json</type> )
16172 <returnvalue>record</returnvalue>
16173 </para>
16174 <para role="func_signature">
16175 <indexterm>
16176 <primary>jsonb_to_record</primary>
16177 </indexterm>
16178 <function>jsonb_to_record</function> ( <type>jsonb</type> )
16179 <returnvalue>record</returnvalue>
16180 </para>
16181 <para>
16182 Expands the top-level JSON object to a row having the composite type
16183 defined by an <literal>AS</literal> clause. (As with all functions
16184 returning <type>record</type>, the calling query must explicitly
16185 define the structure of the record with an <literal>AS</literal>
16186 clause.) The output record is filled from fields of the JSON object,
16187 in the same way as described above
16188 for <function>json[b]_populate_record</function>. Since there is no
16189 input record value, unmatched columns are always filled with nulls.
16190 </para>
16191 <para>
16192 <literal>create type myrowtype as (a int, b text);</literal>
16193 </para>
16194 <para>
16195 <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>
16196 <returnvalue></returnvalue>
16197 <programlisting>
16198 a | b | c | d | r
16199 ---+---------+---------+---+---------------
16200 1 | [1,2,3] | {1,2,3} | | (123,"a b c")
16201 </programlisting>
16202 </para></entry>
16203 </row>
16205 <row>
16206 <entry role="func_table_entry"><para role="func_signature">
16207 <indexterm>
16208 <primary>json_to_recordset</primary>
16209 </indexterm>
16210 <function>json_to_recordset</function> ( <type>json</type> )
16211 <returnvalue>setof record</returnvalue>
16212 </para>
16213 <para role="func_signature">
16214 <indexterm>
16215 <primary>jsonb_to_recordset</primary>
16216 </indexterm>
16217 <function>jsonb_to_recordset</function> ( <type>jsonb</type> )
16218 <returnvalue>setof record</returnvalue>
16219 </para>
16220 <para>
16221 Expands the top-level JSON array of objects to a set of rows having
16222 the composite type defined by an <literal>AS</literal> clause. (As
16223 with all functions returning <type>record</type>, the calling query
16224 must explicitly define the structure of the record with
16225 an <literal>AS</literal> clause.) Each element of the JSON array is
16226 processed as described above
16227 for <function>json[b]_populate_record</function>.
16228 </para>
16229 <para>
16230 <literal>select * from json_to_recordset('[{"a":1,"b":"foo"}, {"a":"2","c":"bar"}]') as x(a int, b text)</literal>
16231 <returnvalue></returnvalue>
16232 <programlisting>
16233 a | b
16234 ---+-----
16235 1 | foo
16237 </programlisting>
16238 </para></entry>
16239 </row>
16241 <row>
16242 <entry role="func_table_entry"><para role="func_signature">
16243 <indexterm>
16244 <primary>jsonb_set</primary>
16245 </indexterm>
16246 <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> )
16247 <returnvalue>jsonb</returnvalue>
16248 </para>
16249 <para>
16250 Returns <parameter>target</parameter>
16251 with the item designated by <parameter>path</parameter>
16252 replaced by <parameter>new_value</parameter>, or with
16253 <parameter>new_value</parameter> added if
16254 <parameter>create_if_missing</parameter> is true (which is the
16255 default) and the item designated by <parameter>path</parameter>
16256 does not exist.
16257 All earlier steps in the path must exist, or
16258 the <parameter>target</parameter> is returned unchanged.
16259 As with the path oriented operators, negative integers that
16260 appear in the <parameter>path</parameter> count from the end
16261 of JSON arrays.
16262 If the last path step is an array index that is out of range,
16263 and <parameter>create_if_missing</parameter> is true, the new
16264 value is added at the beginning of the array if the index is negative,
16265 or at the end of the array if it is positive.
16266 </para>
16267 <para>
16268 <literal>jsonb_set('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', '[2,3,4]', false)</literal>
16269 <returnvalue>[{"f1": [2, 3, 4], "f2": null}, 2, null, 3]</returnvalue>
16270 </para>
16271 <para>
16272 <literal>jsonb_set('[{"f1":1,"f2":null},2]', '{0,f3}', '[2,3,4]')</literal>
16273 <returnvalue>[{"f1": 1, "f2": null, "f3": [2, 3, 4]}, 2]</returnvalue>
16274 </para></entry>
16275 </row>
16277 <row>
16278 <entry role="func_table_entry"><para role="func_signature">
16279 <indexterm>
16280 <primary>jsonb_set_lax</primary>
16281 </indexterm>
16282 <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> )
16283 <returnvalue>jsonb</returnvalue>
16284 </para>
16285 <para>
16286 If <parameter>new_value</parameter> is not <literal>NULL</literal>,
16287 behaves identically to <literal>jsonb_set</literal>. Otherwise behaves
16288 according to the value
16289 of <parameter>null_value_treatment</parameter> which must be one
16290 of <literal>'raise_exception'</literal>,
16291 <literal>'use_json_null'</literal>, <literal>'delete_key'</literal>, or
16292 <literal>'return_target'</literal>. The default is
16293 <literal>'use_json_null'</literal>.
16294 </para>
16295 <para>
16296 <literal>jsonb_set_lax('[{"f1":1,"f2":null},2,null,3]', '{0,f1}', null)</literal>
16297 <returnvalue>[{"f1": null, "f2": null}, 2, null, 3]</returnvalue>
16298 </para>
16299 <para>
16300 <literal>jsonb_set_lax('[{"f1":99,"f2":null},2]', '{0,f3}', null, true, 'return_target')</literal>
16301 <returnvalue>[{"f1": 99, "f2": null}, 2]</returnvalue>
16302 </para></entry>
16303 </row>
16305 <row>
16306 <entry role="func_table_entry"><para role="func_signature">
16307 <indexterm>
16308 <primary>jsonb_insert</primary>
16309 </indexterm>
16310 <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> )
16311 <returnvalue>jsonb</returnvalue>
16312 </para>
16313 <para>
16314 Returns <parameter>target</parameter>
16315 with <parameter>new_value</parameter> inserted. If the item
16316 designated by the <parameter>path</parameter> is an array
16317 element, <parameter>new_value</parameter> will be inserted before
16318 that item if <parameter>insert_after</parameter> is false (which
16319 is the default), or after it
16320 if <parameter>insert_after</parameter> is true. If the item
16321 designated by the <parameter>path</parameter> is an object
16322 field, <parameter>new_value</parameter> will be inserted only if
16323 the object does not already contain that key.
16324 All earlier steps in the path must exist, or
16325 the <parameter>target</parameter> is returned unchanged.
16326 As with the path oriented operators, negative integers that
16327 appear in the <parameter>path</parameter> count from the end
16328 of JSON arrays.
16329 If the last path step is an array index that is out of range, the new
16330 value is added at the beginning of the array if the index is negative,
16331 or at the end of the array if it is positive.
16332 </para>
16333 <para>
16334 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"')</literal>
16335 <returnvalue>{"a": [0, "new_value", 1, 2]}</returnvalue>
16336 </para>
16337 <para>
16338 <literal>jsonb_insert('{"a": [0,1,2]}', '{a, 1}', '"new_value"', true)</literal>
16339 <returnvalue>{"a": [0, 1, "new_value", 2]}</returnvalue>
16340 </para></entry>
16341 </row>
16343 <row>
16344 <entry role="func_table_entry"><para role="func_signature">
16345 <indexterm>
16346 <primary>json_strip_nulls</primary>
16347 </indexterm>
16348 <function>json_strip_nulls</function> ( <type>json</type> )
16349 <returnvalue>json</returnvalue>
16350 </para>
16351 <para role="func_signature">
16352 <indexterm>
16353 <primary>jsonb_strip_nulls</primary>
16354 </indexterm>
16355 <function>jsonb_strip_nulls</function> ( <type>jsonb</type> )
16356 <returnvalue>jsonb</returnvalue>
16357 </para>
16358 <para>
16359 Deletes all object fields that have null values from the given JSON
16360 value, recursively. Null values that are not object fields are
16361 untouched.
16362 </para>
16363 <para>
16364 <literal>json_strip_nulls('[{"f1":1, "f2":null}, 2, null, 3]')</literal>
16365 <returnvalue>[{"f1":1},2,null,3]</returnvalue>
16366 </para></entry>
16367 </row>
16369 <row>
16370 <entry role="func_table_entry"><para role="func_signature">
16371 <indexterm>
16372 <primary>jsonb_path_exists</primary>
16373 </indexterm>
16374 <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> )
16375 <returnvalue>boolean</returnvalue>
16376 </para>
16377 <para>
16378 Checks whether the JSON path returns any item for the specified JSON
16379 value.
16380 If the <parameter>vars</parameter> argument is specified, it must
16381 be a JSON object, and its fields provide named values to be
16382 substituted into the <type>jsonpath</type> expression.
16383 If the <parameter>silent</parameter> argument is specified and
16384 is <literal>true</literal>, the function suppresses the same errors
16385 as the <literal>@?</literal> and <literal>@@</literal> operators do.
16386 </para>
16387 <para>
16388 <literal>jsonb_path_exists('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16389 <returnvalue>t</returnvalue>
16390 </para></entry>
16391 </row>
16393 <row>
16394 <entry role="func_table_entry"><para role="func_signature">
16395 <indexterm>
16396 <primary>jsonb_path_match</primary>
16397 </indexterm>
16398 <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> )
16399 <returnvalue>boolean</returnvalue>
16400 </para>
16401 <para>
16402 Returns the result of a JSON path predicate check for the specified
16403 JSON value. Only the first item of the result is taken into account.
16404 If the result is not Boolean, then <literal>NULL</literal> is returned.
16405 The optional <parameter>vars</parameter>
16406 and <parameter>silent</parameter> arguments act the same as
16407 for <function>jsonb_path_exists</function>.
16408 </para>
16409 <para>
16410 <literal>jsonb_path_match('{"a":[1,2,3,4,5]}', 'exists($.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max))', '{"min":2, "max":4}')</literal>
16411 <returnvalue>t</returnvalue>
16412 </para></entry>
16413 </row>
16415 <row>
16416 <entry role="func_table_entry"><para role="func_signature">
16417 <indexterm>
16418 <primary>jsonb_path_query</primary>
16419 </indexterm>
16420 <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> )
16421 <returnvalue>setof jsonb</returnvalue>
16422 </para>
16423 <para>
16424 Returns all JSON items returned by the JSON path for the specified
16425 JSON value.
16426 The optional <parameter>vars</parameter>
16427 and <parameter>silent</parameter> arguments act the same as
16428 for <function>jsonb_path_exists</function>.
16429 </para>
16430 <para>
16431 <literal>select * from jsonb_path_query('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16432 <returnvalue></returnvalue>
16433 <programlisting>
16434 jsonb_path_query
16435 ------------------
16439 </programlisting>
16440 </para></entry>
16441 </row>
16443 <row>
16444 <entry role="func_table_entry"><para role="func_signature">
16445 <indexterm>
16446 <primary>jsonb_path_query_array</primary>
16447 </indexterm>
16448 <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> )
16449 <returnvalue>jsonb</returnvalue>
16450 </para>
16451 <para>
16452 Returns all JSON items returned by the JSON path for the specified
16453 JSON value, as a JSON array.
16454 The optional <parameter>vars</parameter>
16455 and <parameter>silent</parameter> arguments act the same as
16456 for <function>jsonb_path_exists</function>.
16457 </para>
16458 <para>
16459 <literal>jsonb_path_query_array('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16460 <returnvalue>[2, 3, 4]</returnvalue>
16461 </para></entry>
16462 </row>
16464 <row>
16465 <entry role="func_table_entry"><para role="func_signature">
16466 <indexterm>
16467 <primary>jsonb_path_query_first</primary>
16468 </indexterm>
16469 <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> )
16470 <returnvalue>jsonb</returnvalue>
16471 </para>
16472 <para>
16473 Returns the first JSON item returned by the JSON path for the
16474 specified JSON value. Returns <literal>NULL</literal> if there are no
16475 results.
16476 The optional <parameter>vars</parameter>
16477 and <parameter>silent</parameter> arguments act the same as
16478 for <function>jsonb_path_exists</function>.
16479 </para>
16480 <para>
16481 <literal>jsonb_path_query_first('{"a":[1,2,3,4,5]}', '$.a[*] ? (@ >= $min &amp;&amp; @ &lt;= $max)', '{"min":2, "max":4}')</literal>
16482 <returnvalue>2</returnvalue>
16483 </para></entry>
16484 </row>
16486 <row>
16487 <entry role="func_table_entry"><para role="func_signature">
16488 <indexterm>
16489 <primary>jsonb_path_exists_tz</primary>
16490 </indexterm>
16491 <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> )
16492 <returnvalue>boolean</returnvalue>
16493 </para>
16494 <para role="func_signature">
16495 <indexterm>
16496 <primary>jsonb_path_match_tz</primary>
16497 </indexterm>
16498 <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> )
16499 <returnvalue>boolean</returnvalue>
16500 </para>
16501 <para role="func_signature">
16502 <indexterm>
16503 <primary>jsonb_path_query_tz</primary>
16504 </indexterm>
16505 <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> )
16506 <returnvalue>setof jsonb</returnvalue>
16507 </para>
16508 <para role="func_signature">
16509 <indexterm>
16510 <primary>jsonb_path_query_array_tz</primary>
16511 </indexterm>
16512 <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> )
16513 <returnvalue>jsonb</returnvalue>
16514 </para>
16515 <para role="func_signature">
16516 <indexterm>
16517 <primary>jsonb_path_query_first_tz</primary>
16518 </indexterm>
16519 <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> )
16520 <returnvalue>jsonb</returnvalue>
16521 </para>
16522 <para>
16523 These functions act like their counterparts described above without
16524 the <literal>_tz</literal> suffix, except that these functions support
16525 comparisons of date/time values that require timezone-aware
16526 conversions. The example below requires interpretation of the
16527 date-only value <literal>2015-08-02</literal> as a timestamp with time
16528 zone, so the result depends on the current
16529 <xref linkend="guc-timezone"/> setting. Due to this dependency, these
16530 functions are marked as stable, which means these functions cannot be
16531 used in indexes. Their counterparts are immutable, and so can be used
16532 in indexes; but they will throw errors if asked to make such
16533 comparisons.
16534 </para>
16535 <para>
16536 <literal>jsonb_path_exists_tz('["2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime() &lt; "2015-08-02".datetime())')</literal>
16537 <returnvalue>t</returnvalue>
16538 </para></entry>
16539 </row>
16541 <row>
16542 <entry role="func_table_entry"><para role="func_signature">
16543 <indexterm>
16544 <primary>jsonb_pretty</primary>
16545 </indexterm>
16546 <function>jsonb_pretty</function> ( <type>jsonb</type> )
16547 <returnvalue>text</returnvalue>
16548 </para>
16549 <para>
16550 Converts the given JSON value to pretty-printed, indented text.
16551 </para>
16552 <para>
16553 <literal>jsonb_pretty('[{"f1":1,"f2":null}, 2]')</literal>
16554 <returnvalue></returnvalue>
16555 <programlisting>
16558 "f1": 1,
16559 "f2": null
16563 </programlisting>
16564 </para></entry>
16565 </row>
16567 <row>
16568 <entry role="func_table_entry"><para role="func_signature">
16569 <indexterm>
16570 <primary>json_typeof</primary>
16571 </indexterm>
16572 <function>json_typeof</function> ( <type>json</type> )
16573 <returnvalue>text</returnvalue>
16574 </para>
16575 <para role="func_signature">
16576 <indexterm>
16577 <primary>jsonb_typeof</primary>
16578 </indexterm>
16579 <function>jsonb_typeof</function> ( <type>jsonb</type> )
16580 <returnvalue>text</returnvalue>
16581 </para>
16582 <para>
16583 Returns the type of the top-level JSON value as a text string.
16584 Possible types are
16585 <literal>object</literal>, <literal>array</literal>,
16586 <literal>string</literal>, <literal>number</literal>,
16587 <literal>boolean</literal>, and <literal>null</literal>.
16588 (The <literal>null</literal> result should not be confused
16589 with an SQL NULL; see the examples.)
16590 </para>
16591 <para>
16592 <literal>json_typeof('-123.4')</literal>
16593 <returnvalue>number</returnvalue>
16594 </para>
16595 <para>
16596 <literal>json_typeof('null'::json)</literal>
16597 <returnvalue>null</returnvalue>
16598 </para>
16599 <para>
16600 <literal>json_typeof(NULL::json) IS NULL</literal>
16601 <returnvalue>t</returnvalue>
16602 </para></entry>
16603 </row>
16604 </tbody>
16605 </tgroup>
16606 </table>
16608 <para>
16609 See also <xref linkend="functions-aggregate"/> for the aggregate
16610 function <function>json_agg</function> which aggregates record
16611 values as JSON, the aggregate function
16612 <function>json_object_agg</function> which aggregates pairs of values
16613 into a JSON object, and their <type>jsonb</type> equivalents,
16614 <function>jsonb_agg</function> and <function>jsonb_object_agg</function>.
16615 </para>
16616 </sect2>
16618 <sect2 id="functions-sqljson-path">
16619 <title>The SQL/JSON Path Language</title>
16621 <indexterm zone="functions-sqljson-path">
16622 <primary>SQL/JSON path language</primary>
16623 </indexterm>
16625 <para>
16626 SQL/JSON path expressions specify the items to be retrieved
16627 from the JSON data, similar to XPath expressions used
16628 for SQL access to XML. In <productname>PostgreSQL</productname>,
16629 path expressions are implemented as the <type>jsonpath</type>
16630 data type and can use any elements described in
16631 <xref linkend="datatype-jsonpath"/>.
16632 </para>
16634 <para>
16635 JSON query functions and operators
16636 pass the provided path expression to the <firstterm>path engine</firstterm>
16637 for evaluation. If the expression matches the queried JSON data,
16638 the corresponding JSON item, or set of items, is returned.
16639 Path expressions are written in the SQL/JSON path language
16640 and can include arithmetic expressions and functions.
16641 </para>
16643 <para>
16644 A path expression consists of a sequence of elements allowed
16645 by the <type>jsonpath</type> data type.
16646 The path expression is normally evaluated from left to right, but
16647 you can use parentheses to change the order of operations.
16648 If the evaluation is successful, a sequence of JSON items is produced,
16649 and the evaluation result is returned to the JSON query function
16650 that completes the specified computation.
16651 </para>
16653 <para>
16654 To refer to the JSON value being queried (the
16655 <firstterm>context item</firstterm>), use the <literal>$</literal> variable
16656 in the path expression. It can be followed by one or more
16657 <link linkend="type-jsonpath-accessors">accessor operators</link>,
16658 which go down the JSON structure level by level to retrieve sub-items
16659 of the context item. Each operator that follows deals with the
16660 result of the previous evaluation step.
16661 </para>
16663 <para>
16664 For example, suppose you have some JSON data from a GPS tracker that you
16665 would like to parse, such as:
16666 <programlisting>
16668 "track": {
16669 "segments": [
16671 "location": [ 47.763, 13.4034 ],
16672 "start time": "2018-10-14 10:05:14",
16673 "HR": 73
16676 "location": [ 47.706, 13.2635 ],
16677 "start time": "2018-10-14 10:39:21",
16678 "HR": 135
16683 </programlisting>
16684 </para>
16686 <para>
16687 To retrieve the available track segments, you need to use the
16688 <literal>.<replaceable>key</replaceable></literal> accessor
16689 operator to descend through surrounding JSON objects:
16690 <programlisting>
16691 $.track.segments
16692 </programlisting>
16693 </para>
16695 <para>
16696 To retrieve the contents of an array, you typically use the
16697 <literal>[*]</literal> operator. For example,
16698 the following path will return the location coordinates for all
16699 the available track segments:
16700 <programlisting>
16701 $.track.segments[*].location
16702 </programlisting>
16703 </para>
16705 <para>
16706 To return the coordinates of the first segment only, you can
16707 specify the corresponding subscript in the <literal>[]</literal>
16708 accessor operator. Recall that JSON array indexes are 0-relative:
16709 <programlisting>
16710 $.track.segments[0].location
16711 </programlisting>
16712 </para>
16714 <para>
16715 The result of each path evaluation step can be processed
16716 by one or more <type>jsonpath</type> operators and methods
16717 listed in <xref linkend="functions-sqljson-path-operators"/>.
16718 Each method name must be preceded by a dot. For example,
16719 you can get the size of an array:
16720 <programlisting>
16721 $.track.segments.size()
16722 </programlisting>
16723 More examples of using <type>jsonpath</type> operators
16724 and methods within path expressions appear below in
16725 <xref linkend="functions-sqljson-path-operators"/>.
16726 </para>
16728 <para>
16729 When defining a path, you can also use one or more
16730 <firstterm>filter expressions</firstterm> that work similarly to the
16731 <literal>WHERE</literal> clause in SQL. A filter expression begins with
16732 a question mark and provides a condition in parentheses:
16734 <programlisting>
16735 ? (<replaceable>condition</replaceable>)
16736 </programlisting>
16737 </para>
16739 <para>
16740 Filter expressions must be written just after the path evaluation step
16741 to which they should apply. The result of that step is filtered to include
16742 only those items that satisfy the provided condition. SQL/JSON defines
16743 three-valued logic, so the condition can be <literal>true</literal>, <literal>false</literal>,
16744 or <literal>unknown</literal>. The <literal>unknown</literal> value
16745 plays the same role as SQL <literal>NULL</literal> and can be tested
16746 for with the <literal>is unknown</literal> predicate. Further path
16747 evaluation steps use only those items for which the filter expression
16748 returned <literal>true</literal>.
16749 </para>
16751 <para>
16752 The functions and operators that can be used in filter expressions are
16753 listed in <xref linkend="functions-sqljson-filter-ex-table"/>. Within a
16754 filter expression, the <literal>@</literal> variable denotes the value
16755 being filtered (i.e., one result of the preceding path step). You can
16756 write accessor operators after <literal>@</literal> to retrieve component
16757 items.
16758 </para>
16760 <para>
16761 For example, suppose you would like to retrieve all heart rate values higher
16762 than 130. You can achieve this using the following expression:
16763 <programlisting>
16764 $.track.segments[*].HR ? (@ &gt; 130)
16765 </programlisting>
16766 </para>
16768 <para>
16769 To get the start times of segments with such values, you have to
16770 filter out irrelevant segments before returning the start times, so the
16771 filter expression is applied to the previous step, and the path used
16772 in the condition is different:
16773 <programlisting>
16774 $.track.segments[*] ? (@.HR &gt; 130)."start time"
16775 </programlisting>
16776 </para>
16778 <para>
16779 You can use several filter expressions in sequence, if required. For
16780 example, the following expression selects start times of all segments that
16781 contain locations with relevant coordinates and high heart rate values:
16782 <programlisting>
16783 $.track.segments[*] ? (@.location[1] &lt; 13.4) ? (@.HR &gt; 130)."start time"
16784 </programlisting>
16785 </para>
16787 <para>
16788 Using filter expressions at different nesting levels is also allowed.
16789 The following example first filters all segments by location, and then
16790 returns high heart rate values for these segments, if available:
16791 <programlisting>
16792 $.track.segments[*] ? (@.location[1] &lt; 13.4).HR ? (@ &gt; 130)
16793 </programlisting>
16794 </para>
16796 <para>
16797 You can also nest filter expressions within each other:
16798 <programlisting>
16799 $.track ? (exists(@.segments[*] ? (@.HR &gt; 130))).segments.size()
16800 </programlisting>
16801 This expression returns the size of the track if it contains any
16802 segments with high heart rate values, or an empty sequence otherwise.
16803 </para>
16805 <para>
16806 <productname>PostgreSQL</productname>'s implementation of the SQL/JSON path
16807 language has the following deviations from the SQL/JSON standard:
16808 </para>
16810 <itemizedlist>
16811 <listitem>
16812 <para>
16813 A path expression can be a Boolean predicate, although the SQL/JSON
16814 standard allows predicates only in filters. This is necessary for
16815 implementation of the <literal>@@</literal> operator. For example,
16816 the following <type>jsonpath</type> expression is valid in
16817 <productname>PostgreSQL</productname>:
16818 <programlisting>
16819 $.track.segments[*].HR &lt; 70
16820 </programlisting>
16821 </para>
16822 </listitem>
16824 <listitem>
16825 <para>
16826 There are minor differences in the interpretation of regular
16827 expression patterns used in <literal>like_regex</literal> filters, as
16828 described in <xref linkend="jsonpath-regular-expressions"/>.
16829 </para>
16830 </listitem>
16831 </itemizedlist>
16833 <sect3 id="strict-and-lax-modes">
16834 <title>Strict and Lax Modes</title>
16835 <para>
16836 When you query JSON data, the path expression may not match the
16837 actual JSON data structure. An attempt to access a non-existent
16838 member of an object or element of an array results in a
16839 structural error. SQL/JSON path expressions have two modes
16840 of handling structural errors:
16841 </para>
16843 <itemizedlist>
16844 <listitem>
16845 <para>
16846 lax (default) &mdash; the path engine implicitly adapts
16847 the queried data to the specified path.
16848 Any remaining structural errors are suppressed and converted
16849 to empty SQL/JSON sequences.
16850 </para>
16851 </listitem>
16852 <listitem>
16853 <para>
16854 strict &mdash; if a structural error occurs, an error is raised.
16855 </para>
16856 </listitem>
16857 </itemizedlist>
16859 <para>
16860 The lax mode facilitates matching of a JSON document structure and path
16861 expression if the JSON data does not conform to the expected schema.
16862 If an operand does not match the requirements of a particular operation,
16863 it can be automatically wrapped as an SQL/JSON array or unwrapped by
16864 converting its elements into an SQL/JSON sequence before performing
16865 this operation. Besides, comparison operators automatically unwrap their
16866 operands in the lax mode, so you can compare SQL/JSON arrays
16867 out-of-the-box. An array of size 1 is considered equal to its sole element.
16868 Automatic unwrapping is not performed only when:
16869 <itemizedlist>
16870 <listitem>
16871 <para>
16872 The path expression contains <literal>type()</literal> or
16873 <literal>size()</literal> methods that return the type
16874 and the number of elements in the array, respectively.
16875 </para>
16876 </listitem>
16877 <listitem>
16878 <para>
16879 The queried JSON data contain nested arrays. In this case, only
16880 the outermost array is unwrapped, while all the inner arrays
16881 remain unchanged. Thus, implicit unwrapping can only go one
16882 level down within each path evaluation step.
16883 </para>
16884 </listitem>
16885 </itemizedlist>
16886 </para>
16888 <para>
16889 For example, when querying the GPS data listed above, you can
16890 abstract from the fact that it stores an array of segments
16891 when using the lax mode:
16892 <programlisting>
16893 lax $.track.segments.location
16894 </programlisting>
16895 </para>
16897 <para>
16898 In the strict mode, the specified path must exactly match the structure of
16899 the queried JSON document to return an SQL/JSON item, so using this
16900 path expression will cause an error. To get the same result as in
16901 the lax mode, you have to explicitly unwrap the
16902 <literal>segments</literal> array:
16903 <programlisting>
16904 strict $.track.segments[*].location
16905 </programlisting>
16906 </para>
16908 <para>
16909 The <literal>.**</literal> accessor can lead to surprising results
16910 when using the lax mode. For instance, the following query selects every
16911 <literal>HR</literal> value twice:
16912 <programlisting>
16913 lax $.**.HR
16914 </programlisting>
16915 This happens because the <literal>.**</literal> accessor selects both
16916 the <literal>segments</literal> array and each of its elements, while
16917 the <literal>.HR</literal> accessor automatically unwraps arrays when
16918 using the lax mode. To avoid surprising results, we recommend using
16919 the <literal>.**</literal> accessor only in the strict mode. The
16920 following query selects each <literal>HR</literal> value just once:
16921 <programlisting>
16922 strict $.**.HR
16923 </programlisting>
16924 </para>
16926 </sect3>
16928 <sect3 id="functions-sqljson-path-operators">
16929 <title>SQL/JSON Path Operators and Methods</title>
16931 <para>
16932 <xref linkend="functions-sqljson-op-table"/> shows the operators and
16933 methods available in <type>jsonpath</type>. Note that while the unary
16934 operators and methods can be applied to multiple values resulting from a
16935 preceding path step, the binary operators (addition etc.) can only be
16936 applied to single values.
16937 </para>
16939 <table id="functions-sqljson-op-table">
16940 <title><type>jsonpath</type> Operators and Methods</title>
16941 <tgroup cols="1">
16942 <thead>
16943 <row>
16944 <entry role="func_table_entry"><para role="func_signature">
16945 Operator/Method
16946 </para>
16947 <para>
16948 Description
16949 </para>
16950 <para>
16951 Example(s)
16952 </para></entry>
16953 </row>
16954 </thead>
16956 <tbody>
16957 <row>
16958 <entry role="func_table_entry"><para role="func_signature">
16959 <replaceable>number</replaceable> <literal>+</literal> <replaceable>number</replaceable>
16960 <returnvalue><replaceable>number</replaceable></returnvalue>
16961 </para>
16962 <para>
16963 Addition
16964 </para>
16965 <para>
16966 <literal>jsonb_path_query('[2]', '$[0] + 3')</literal>
16967 <returnvalue>5</returnvalue>
16968 </para></entry>
16969 </row>
16971 <row>
16972 <entry role="func_table_entry"><para role="func_signature">
16973 <literal>+</literal> <replaceable>number</replaceable>
16974 <returnvalue><replaceable>number</replaceable></returnvalue>
16975 </para>
16976 <para>
16977 Unary plus (no operation); unlike addition, this can iterate over
16978 multiple values
16979 </para>
16980 <para>
16981 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '+ $.x')</literal>
16982 <returnvalue>[2, 3, 4]</returnvalue>
16983 </para></entry>
16984 </row>
16986 <row>
16987 <entry role="func_table_entry"><para role="func_signature">
16988 <replaceable>number</replaceable> <literal>-</literal> <replaceable>number</replaceable>
16989 <returnvalue><replaceable>number</replaceable></returnvalue>
16990 </para>
16991 <para>
16992 Subtraction
16993 </para>
16994 <para>
16995 <literal>jsonb_path_query('[2]', '7 - $[0]')</literal>
16996 <returnvalue>5</returnvalue>
16997 </para></entry>
16998 </row>
17000 <row>
17001 <entry role="func_table_entry"><para role="func_signature">
17002 <literal>-</literal> <replaceable>number</replaceable>
17003 <returnvalue><replaceable>number</replaceable></returnvalue>
17004 </para>
17005 <para>
17006 Negation; unlike subtraction, this can iterate over
17007 multiple values
17008 </para>
17009 <para>
17010 <literal>jsonb_path_query_array('{"x": [2,3,4]}', '- $.x')</literal>
17011 <returnvalue>[-2, -3, -4]</returnvalue>
17012 </para></entry>
17013 </row>
17015 <row>
17016 <entry role="func_table_entry"><para role="func_signature">
17017 <replaceable>number</replaceable> <literal>*</literal> <replaceable>number</replaceable>
17018 <returnvalue><replaceable>number</replaceable></returnvalue>
17019 </para>
17020 <para>
17021 Multiplication
17022 </para>
17023 <para>
17024 <literal>jsonb_path_query('[4]', '2 * $[0]')</literal>
17025 <returnvalue>8</returnvalue>
17026 </para></entry>
17027 </row>
17029 <row>
17030 <entry role="func_table_entry"><para role="func_signature">
17031 <replaceable>number</replaceable> <literal>/</literal> <replaceable>number</replaceable>
17032 <returnvalue><replaceable>number</replaceable></returnvalue>
17033 </para>
17034 <para>
17035 Division
17036 </para>
17037 <para>
17038 <literal>jsonb_path_query('[8.5]', '$[0] / 2')</literal>
17039 <returnvalue>4.2500000000000000</returnvalue>
17040 </para></entry>
17041 </row>
17043 <row>
17044 <entry role="func_table_entry"><para role="func_signature">
17045 <replaceable>number</replaceable> <literal>%</literal> <replaceable>number</replaceable>
17046 <returnvalue><replaceable>number</replaceable></returnvalue>
17047 </para>
17048 <para>
17049 Modulo (remainder)
17050 </para>
17051 <para>
17052 <literal>jsonb_path_query('[32]', '$[0] % 10')</literal>
17053 <returnvalue>2</returnvalue>
17054 </para></entry>
17055 </row>
17057 <row>
17058 <entry role="func_table_entry"><para role="func_signature">
17059 <replaceable>value</replaceable> <literal>.</literal> <literal>type()</literal>
17060 <returnvalue><replaceable>string</replaceable></returnvalue>
17061 </para>
17062 <para>
17063 Type of the JSON item (see <function>json_typeof</function>)
17064 </para>
17065 <para>
17066 <literal>jsonb_path_query_array('[1, "2", {}]', '$[*].type()')</literal>
17067 <returnvalue>["number", "string", "object"]</returnvalue>
17068 </para></entry>
17069 </row>
17071 <row>
17072 <entry role="func_table_entry"><para role="func_signature">
17073 <replaceable>value</replaceable> <literal>.</literal> <literal>size()</literal>
17074 <returnvalue><replaceable>number</replaceable></returnvalue>
17075 </para>
17076 <para>
17077 Size of the JSON item (number of array elements, or 1 if not an
17078 array)
17079 </para>
17080 <para>
17081 <literal>jsonb_path_query('{"m": [11, 15]}', '$.m.size()')</literal>
17082 <returnvalue>2</returnvalue>
17083 </para></entry>
17084 </row>
17086 <row>
17087 <entry role="func_table_entry"><para role="func_signature">
17088 <replaceable>value</replaceable> <literal>.</literal> <literal>double()</literal>
17089 <returnvalue><replaceable>number</replaceable></returnvalue>
17090 </para>
17091 <para>
17092 Approximate floating-point number converted from a JSON number or
17093 string
17094 </para>
17095 <para>
17096 <literal>jsonb_path_query('{"len": "1.9"}', '$.len.double() * 2')</literal>
17097 <returnvalue>3.8</returnvalue>
17098 </para></entry>
17099 </row>
17101 <row>
17102 <entry role="func_table_entry"><para role="func_signature">
17103 <replaceable>number</replaceable> <literal>.</literal> <literal>ceiling()</literal>
17104 <returnvalue><replaceable>number</replaceable></returnvalue>
17105 </para>
17106 <para>
17107 Nearest integer greater than or equal to the given number
17108 </para>
17109 <para>
17110 <literal>jsonb_path_query('{"h": 1.3}', '$.h.ceiling()')</literal>
17111 <returnvalue>2</returnvalue>
17112 </para></entry>
17113 </row>
17115 <row>
17116 <entry role="func_table_entry"><para role="func_signature">
17117 <replaceable>number</replaceable> <literal>.</literal> <literal>floor()</literal>
17118 <returnvalue><replaceable>number</replaceable></returnvalue>
17119 </para>
17120 <para>
17121 Nearest integer less than or equal to the given number
17122 </para>
17123 <para>
17124 <literal>jsonb_path_query('{"h": 1.7}', '$.h.floor()')</literal>
17125 <returnvalue>1</returnvalue>
17126 </para></entry>
17127 </row>
17129 <row>
17130 <entry role="func_table_entry"><para role="func_signature">
17131 <replaceable>number</replaceable> <literal>.</literal> <literal>abs()</literal>
17132 <returnvalue><replaceable>number</replaceable></returnvalue>
17133 </para>
17134 <para>
17135 Absolute value of the given number
17136 </para>
17137 <para>
17138 <literal>jsonb_path_query('{"z": -0.3}', '$.z.abs()')</literal>
17139 <returnvalue>0.3</returnvalue>
17140 </para></entry>
17141 </row>
17143 <row>
17144 <entry role="func_table_entry"><para role="func_signature">
17145 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime()</literal>
17146 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
17147 (see note)
17148 </para>
17149 <para>
17150 Date/time value converted from a string
17151 </para>
17152 <para>
17153 <literal>jsonb_path_query('["2015-8-1", "2015-08-12"]', '$[*] ? (@.datetime() &lt; "2015-08-2".datetime())')</literal>
17154 <returnvalue>"2015-8-1"</returnvalue>
17155 </para></entry>
17156 </row>
17158 <row>
17159 <entry role="func_table_entry"><para role="func_signature">
17160 <replaceable>string</replaceable> <literal>.</literal> <literal>datetime(<replaceable>template</replaceable>)</literal>
17161 <returnvalue><replaceable>datetime_type</replaceable></returnvalue>
17162 (see note)
17163 </para>
17164 <para>
17165 Date/time value converted from a string using the
17166 specified <function>to_timestamp</function> template
17167 </para>
17168 <para>
17169 <literal>jsonb_path_query_array('["12:30", "18:40"]', '$[*].datetime("HH24:MI")')</literal>
17170 <returnvalue>["12:30:00", "18:40:00"]</returnvalue>
17171 </para></entry>
17172 </row>
17174 <row>
17175 <entry role="func_table_entry"><para role="func_signature">
17176 <replaceable>object</replaceable> <literal>.</literal> <literal>keyvalue()</literal>
17177 <returnvalue><replaceable>array</replaceable></returnvalue>
17178 </para>
17179 <para>
17180 The object's key-value pairs, represented as an array of objects
17181 containing three fields: <literal>"key"</literal>,
17182 <literal>"value"</literal>, and <literal>"id"</literal>;
17183 <literal>"id"</literal> is a unique identifier of the object the
17184 key-value pair belongs to
17185 </para>
17186 <para>
17187 <literal>jsonb_path_query_array('{"x": "20", "y": 32}', '$.keyvalue()')</literal>
17188 <returnvalue>[{"id": 0, "key": "x", "value": "20"}, {"id": 0, "key": "y", "value": 32}]</returnvalue>
17189 </para></entry>
17190 </row>
17191 </tbody>
17192 </tgroup>
17193 </table>
17195 <note>
17196 <para>
17197 The result type of the <literal>datetime()</literal> and
17198 <literal>datetime(<replaceable>template</replaceable>)</literal>
17199 methods can be <type>date</type>, <type>timetz</type>, <type>time</type>,
17200 <type>timestamptz</type>, or <type>timestamp</type>.
17201 Both methods determine their result type dynamically.
17202 </para>
17203 <para>
17204 The <literal>datetime()</literal> method sequentially tries to
17205 match its input string to the ISO formats
17206 for <type>date</type>, <type>timetz</type>, <type>time</type>,
17207 <type>timestamptz</type>, and <type>timestamp</type>. It stops on
17208 the first matching format and emits the corresponding data type.
17209 </para>
17210 <para>
17211 The <literal>datetime(<replaceable>template</replaceable>)</literal>
17212 method determines the result type according to the fields used in the
17213 provided template string.
17214 </para>
17215 <para>
17216 The <literal>datetime()</literal> and
17217 <literal>datetime(<replaceable>template</replaceable>)</literal> methods
17218 use the same parsing rules as the <literal>to_timestamp</literal> SQL
17219 function does (see <xref linkend="functions-formatting"/>), with three
17220 exceptions. First, these methods don't allow unmatched template
17221 patterns. Second, only the following separators are allowed in the
17222 template string: minus sign, period, solidus (slash), comma, apostrophe,
17223 semicolon, colon and space. Third, separators in the template string
17224 must exactly match the input string.
17225 </para>
17226 <para>
17227 If different date/time types need to be compared, an implicit cast is
17228 applied. A <type>date</type> value can be cast to <type>timestamp</type>
17229 or <type>timestamptz</type>, <type>timestamp</type> can be cast to
17230 <type>timestamptz</type>, and <type>time</type> to <type>timetz</type>.
17231 However, all but the first of these conversions depend on the current
17232 <xref linkend="guc-timezone"/> setting, and thus can only be performed
17233 within timezone-aware <type>jsonpath</type> functions.
17234 </para>
17235 </note>
17237 <para>
17238 <xref linkend="functions-sqljson-filter-ex-table"/> shows the available
17239 filter expression elements.
17240 </para>
17242 <table id="functions-sqljson-filter-ex-table">
17243 <title><type>jsonpath</type> Filter Expression Elements</title>
17244 <tgroup cols="1">
17245 <thead>
17246 <row>
17247 <entry role="func_table_entry"><para role="func_signature">
17248 Predicate/Value
17249 </para>
17250 <para>
17251 Description
17252 </para>
17253 <para>
17254 Example(s)
17255 </para></entry>
17256 </row>
17257 </thead>
17259 <tbody>
17260 <row>
17261 <entry role="func_table_entry"><para role="func_signature">
17262 <replaceable>value</replaceable> <literal>==</literal> <replaceable>value</replaceable>
17263 <returnvalue>boolean</returnvalue>
17264 </para>
17265 <para>
17266 Equality comparison (this, and the other comparison operators, work on
17267 all JSON scalar values)
17268 </para>
17269 <para>
17270 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == 1)')</literal>
17271 <returnvalue>[1, 1]</returnvalue>
17272 </para>
17273 <para>
17274 <literal>jsonb_path_query_array('[1, "a", 1, 3]', '$[*] ? (@ == "a")')</literal>
17275 <returnvalue>["a"]</returnvalue>
17276 </para></entry>
17277 </row>
17279 <row>
17280 <entry role="func_table_entry"><para role="func_signature">
17281 <replaceable>value</replaceable> <literal>!=</literal> <replaceable>value</replaceable>
17282 <returnvalue>boolean</returnvalue>
17283 </para>
17284 <para role="func_signature">
17285 <replaceable>value</replaceable> <literal>&lt;&gt;</literal> <replaceable>value</replaceable>
17286 <returnvalue>boolean</returnvalue>
17287 </para>
17288 <para>
17289 Non-equality comparison
17290 </para>
17291 <para>
17292 <literal>jsonb_path_query_array('[1, 2, 1, 3]', '$[*] ? (@ != 1)')</literal>
17293 <returnvalue>[2, 3]</returnvalue>
17294 </para>
17295 <para>
17296 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;&gt; "b")')</literal>
17297 <returnvalue>["a", "c"]</returnvalue>
17298 </para></entry>
17299 </row>
17301 <row>
17302 <entry role="func_table_entry"><para role="func_signature">
17303 <replaceable>value</replaceable> <literal>&lt;</literal> <replaceable>value</replaceable>
17304 <returnvalue>boolean</returnvalue>
17305 </para>
17306 <para>
17307 Less-than comparison
17308 </para>
17309 <para>
17310 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &lt; 2)')</literal>
17311 <returnvalue>[1]</returnvalue>
17312 </para></entry>
17313 </row>
17315 <row>
17316 <entry role="func_table_entry"><para role="func_signature">
17317 <replaceable>value</replaceable> <literal>&lt;=</literal> <replaceable>value</replaceable>
17318 <returnvalue>boolean</returnvalue>
17319 </para>
17320 <para>
17321 Less-than-or-equal-to comparison
17322 </para>
17323 <para>
17324 <literal>jsonb_path_query_array('["a", "b", "c"]', '$[*] ? (@ &lt;= "b")')</literal>
17325 <returnvalue>["a", "b"]</returnvalue>
17326 </para></entry>
17327 </row>
17329 <row>
17330 <entry role="func_table_entry"><para role="func_signature">
17331 <replaceable>value</replaceable> <literal>&gt;</literal> <replaceable>value</replaceable>
17332 <returnvalue>boolean</returnvalue>
17333 </para>
17334 <para>
17335 Greater-than comparison
17336 </para>
17337 <para>
17338 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt; 2)')</literal>
17339 <returnvalue>[3]</returnvalue>
17340 </para></entry>
17341 </row>
17343 <row>
17344 <entry role="func_table_entry"><para role="func_signature">
17345 <replaceable>value</replaceable> <literal>&gt;=</literal> <replaceable>value</replaceable>
17346 <returnvalue>boolean</returnvalue>
17347 </para>
17348 <para>
17349 Greater-than-or-equal-to comparison
17350 </para>
17351 <para>
17352 <literal>jsonb_path_query_array('[1, 2, 3]', '$[*] ? (@ &gt;= 2)')</literal>
17353 <returnvalue>[2, 3]</returnvalue>
17354 </para></entry>
17355 </row>
17357 <row>
17358 <entry role="func_table_entry"><para role="func_signature">
17359 <literal>true</literal>
17360 <returnvalue>boolean</returnvalue>
17361 </para>
17362 <para>
17363 JSON constant <literal>true</literal>
17364 </para>
17365 <para>
17366 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == true)')</literal>
17367 <returnvalue>{"name": "Chris", "parent": true}</returnvalue>
17368 </para></entry>
17369 </row>
17371 <row>
17372 <entry role="func_table_entry"><para role="func_signature">
17373 <literal>false</literal>
17374 <returnvalue>boolean</returnvalue>
17375 </para>
17376 <para>
17377 JSON constant <literal>false</literal>
17378 </para>
17379 <para>
17380 <literal>jsonb_path_query('[{"name": "John", "parent": false}, {"name": "Chris", "parent": true}]', '$[*] ? (@.parent == false)')</literal>
17381 <returnvalue>{"name": "John", "parent": false}</returnvalue>
17382 </para></entry>
17383 </row>
17385 <row>
17386 <entry role="func_table_entry"><para role="func_signature">
17387 <literal>null</literal>
17388 <returnvalue><replaceable>value</replaceable></returnvalue>
17389 </para>
17390 <para>
17391 JSON constant <literal>null</literal> (note that, unlike in SQL,
17392 comparison to <literal>null</literal> works normally)
17393 </para>
17394 <para>
17395 <literal>jsonb_path_query('[{"name": "Mary", "job": null}, {"name": "Michael", "job": "driver"}]', '$[*] ? (@.job == null) .name')</literal>
17396 <returnvalue>"Mary"</returnvalue>
17397 </para></entry>
17398 </row>
17400 <row>
17401 <entry role="func_table_entry"><para role="func_signature">
17402 <replaceable>boolean</replaceable> <literal>&amp;&amp;</literal> <replaceable>boolean</replaceable>
17403 <returnvalue>boolean</returnvalue>
17404 </para>
17405 <para>
17406 Boolean AND
17407 </para>
17408 <para>
17409 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &gt; 1 &amp;&amp; @ &lt; 5)')</literal>
17410 <returnvalue>3</returnvalue>
17411 </para></entry>
17412 </row>
17414 <row>
17415 <entry role="func_table_entry"><para role="func_signature">
17416 <replaceable>boolean</replaceable> <literal>||</literal> <replaceable>boolean</replaceable>
17417 <returnvalue>boolean</returnvalue>
17418 </para>
17419 <para>
17420 Boolean OR
17421 </para>
17422 <para>
17423 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (@ &lt; 1 || @ &gt; 5)')</literal>
17424 <returnvalue>7</returnvalue>
17425 </para></entry>
17426 </row>
17428 <row>
17429 <entry role="func_table_entry"><para role="func_signature">
17430 <literal>!</literal> <replaceable>boolean</replaceable>
17431 <returnvalue>boolean</returnvalue>
17432 </para>
17433 <para>
17434 Boolean NOT
17435 </para>
17436 <para>
17437 <literal>jsonb_path_query('[1, 3, 7]', '$[*] ? (!(@ &lt; 5))')</literal>
17438 <returnvalue>7</returnvalue>
17439 </para></entry>
17440 </row>
17442 <row>
17443 <entry role="func_table_entry"><para role="func_signature">
17444 <replaceable>boolean</replaceable> <literal>is unknown</literal>
17445 <returnvalue>boolean</returnvalue>
17446 </para>
17447 <para>
17448 Tests whether a Boolean condition is <literal>unknown</literal>.
17449 </para>
17450 <para>
17451 <literal>jsonb_path_query('[-1, 2, 7, "foo"]', '$[*] ? ((@ > 0) is unknown)')</literal>
17452 <returnvalue>"foo"</returnvalue>
17453 </para></entry>
17454 </row>
17456 <row>
17457 <entry role="func_table_entry"><para role="func_signature">
17458 <replaceable>string</replaceable> <literal>like_regex</literal> <replaceable>string</replaceable> <optional> <literal>flag</literal> <replaceable>string</replaceable> </optional>
17459 <returnvalue>boolean</returnvalue>
17460 </para>
17461 <para>
17462 Tests whether the first operand matches the regular expression
17463 given by the second operand, optionally with modifications
17464 described by a string of <literal>flag</literal> characters (see
17465 <xref linkend="jsonpath-regular-expressions"/>).
17466 </para>
17467 <para>
17468 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c")')</literal>
17469 <returnvalue>["abc", "abdacb"]</returnvalue>
17470 </para>
17471 <para>
17472 <literal>jsonb_path_query_array('["abc", "abd", "aBdC", "abdacb", "babc"]', '$[*] ? (@ like_regex "^ab.*c" flag "i")')</literal>
17473 <returnvalue>["abc", "aBdC", "abdacb"]</returnvalue>
17474 </para></entry>
17475 </row>
17477 <row>
17478 <entry role="func_table_entry"><para role="func_signature">
17479 <replaceable>string</replaceable> <literal>starts with</literal> <replaceable>string</replaceable>
17480 <returnvalue>boolean</returnvalue>
17481 </para>
17482 <para>
17483 Tests whether the second operand is an initial substring of the first
17484 operand.
17485 </para>
17486 <para>
17487 <literal>jsonb_path_query('["John Smith", "Mary Stone", "Bob Johnson"]', '$[*] ? (@ starts with "John")')</literal>
17488 <returnvalue>"John Smith"</returnvalue>
17489 </para></entry>
17490 </row>
17492 <row>
17493 <entry role="func_table_entry"><para role="func_signature">
17494 <literal>exists</literal> <literal>(</literal> <replaceable>path_expression</replaceable> <literal>)</literal>
17495 <returnvalue>boolean</returnvalue>
17496 </para>
17497 <para>
17498 Tests whether a path expression matches at least one SQL/JSON item.
17499 Returns <literal>unknown</literal> if the path expression would result
17500 in an error; the second example uses this to avoid a no-such-key error
17501 in strict mode.
17502 </para>
17503 <para>
17504 <literal>jsonb_path_query('{"x": [1, 2], "y": [2, 4]}', 'strict $.* ? (exists (@ ? (@[*] &gt; 2)))')</literal>
17505 <returnvalue>[2, 4]</returnvalue>
17506 </para>
17507 <para>
17508 <literal>jsonb_path_query_array('{"value": 41}', 'strict $ ? (exists (@.name)) .name')</literal>
17509 <returnvalue>[]</returnvalue>
17510 </para></entry>
17511 </row>
17512 </tbody>
17513 </tgroup>
17514 </table>
17516 </sect3>
17518 <sect3 id="jsonpath-regular-expressions">
17519 <title>SQL/JSON Regular Expressions</title>
17521 <indexterm zone="jsonpath-regular-expressions">
17522 <primary><literal>LIKE_REGEX</literal></primary>
17523 <secondary>in SQL/JSON</secondary>
17524 </indexterm>
17526 <para>
17527 SQL/JSON path expressions allow matching text to a regular expression
17528 with the <literal>like_regex</literal> filter. For example, the
17529 following SQL/JSON path query would case-insensitively match all
17530 strings in an array that start with an English vowel:
17531 <programlisting>
17532 $[*] ? (@ like_regex "^[aeiou]" flag "i")
17533 </programlisting>
17534 </para>
17536 <para>
17537 The optional <literal>flag</literal> string may include one or more of
17538 the characters
17539 <literal>i</literal> for case-insensitive match,
17540 <literal>m</literal> to allow <literal>^</literal>
17541 and <literal>$</literal> to match at newlines,
17542 <literal>s</literal> to allow <literal>.</literal> to match a newline,
17543 and <literal>q</literal> to quote the whole pattern (reducing the
17544 behavior to a simple substring match).
17545 </para>
17547 <para>
17548 The SQL/JSON standard borrows its definition for regular expressions
17549 from the <literal>LIKE_REGEX</literal> operator, which in turn uses the
17550 XQuery standard. PostgreSQL does not currently support the
17551 <literal>LIKE_REGEX</literal> operator. Therefore,
17552 the <literal>like_regex</literal> filter is implemented using the
17553 POSIX regular expression engine described in
17554 <xref linkend="functions-posix-regexp"/>. This leads to various minor
17555 discrepancies from standard SQL/JSON behavior, which are cataloged in
17556 <xref linkend="posix-vs-xquery"/>.
17557 Note, however, that the flag-letter incompatibilities described there
17558 do not apply to SQL/JSON, as it translates the XQuery flag letters to
17559 match what the POSIX engine expects.
17560 </para>
17562 <para>
17563 Keep in mind that the pattern argument of <literal>like_regex</literal>
17564 is a JSON path string literal, written according to the rules given in
17565 <xref linkend="datatype-jsonpath"/>. This means in particular that any
17566 backslashes you want to use in the regular expression must be doubled.
17567 For example, to match string values of the root document that contain
17568 only digits:
17569 <programlisting>
17570 $.* ? (@ like_regex "^\\d+$")
17571 </programlisting>
17572 </para>
17573 </sect3>
17574 </sect2>
17576 <sect2 id="functions-sqljson">
17577 <title>SQL/JSON Functions and Expressions</title>
17578 <indexterm zone="functions-json">
17579 <primary>SQL/JSON</primary>
17580 <secondary>functions and expressions</secondary>
17581 </indexterm>
17583 <para>
17584 To provide native support for JSON data types within the SQL environment,
17585 <productname>PostgreSQL</productname> implements the
17586 <firstterm>SQL/JSON data model</firstterm>.
17587 This model comprises sequences of items. Each item can hold SQL scalar
17588 values, with an additional SQL/JSON null value, and composite data structures
17589 that use JSON arrays and objects. The model is a formalization of the implied
17590 data model in the JSON specification
17591 <ulink url="https://tools.ietf.org/html/rfc7159">RFC 7159</ulink>.
17592 </para>
17594 <para>
17595 SQL/JSON allows you to handle JSON data alongside regular SQL data,
17596 with transaction support, including:
17597 </para>
17599 <itemizedlist>
17600 <listitem>
17601 <para>
17602 Uploading JSON data into the database and storing it in
17603 regular SQL columns as character or binary strings.
17604 </para>
17605 </listitem>
17606 <listitem>
17607 <para>
17608 Generating JSON objects and arrays from relational data.
17609 </para>
17610 </listitem>
17611 <listitem>
17612 <para>
17613 Querying JSON data using SQL/JSON query functions and
17614 SQL/JSON path language expressions.
17615 </para>
17616 </listitem>
17617 </itemizedlist>
17619 <para>
17620 There are two groups of SQL/JSON functions.
17621 <link linkend="functions-sqljson-producing">Constructor functions</link>
17622 generate JSON data from values of SQL types.
17623 <link linkend="functions-sqljson-querying">Query functions</link>
17624 evaluate SQL/JSON path language expressions against JSON values
17625 and produce values of SQL/JSON types, which are converted to SQL types.
17626 </para>
17628 <para>
17629 Many SQL/JSON functions have an optional <literal>FORMAT</literal>
17630 clause. This is provided to conform with the SQL standard, but has no
17631 effect except where noted otherwise.
17632 </para>
17634 <para>
17635 <xref linkend="functions-sqljson-producing" /> lists the SQL/JSON
17636 Constructor functions. Each function has a <literal>RETURNING</literal>
17637 clause specifying the data type returned. For the <function>json</function> and
17638 <function>json_scalar</function> functions, this needs to be either <type>json</type> or
17639 <type>jsonb</type>. For the other constructor functions it must be one of <type>json</type>,
17640 <type>jsonb</type>, <type>bytea</type>, a character string type (<type>text</type>, <type>char</type>,
17641 <type>varchar</type>, or <type>nchar</type>), or a type for which there is a cast
17642 from <type>json</type> to that type.
17643 By default, the <type>json</type> type is returned.
17644 </para>
17646 <note>
17647 <para>
17648 Many of the results that can be obtained from the SQL/JSON Constructor
17649 functions can also be obtained by calling
17650 <productname>PostgreSQL</productname>-specific functions detailed in
17651 <xref linkend="functions-json-creation-table" /> and
17652 <xref linkend="functions-aggregate-table"/>.
17653 </para>
17654 </note>
17656 <table id="functions-sqljson-producing">
17657 <title>SQL/JSON Constructor Functions</title>
17658 <tgroup cols="1">
17659 <thead>
17660 <row>
17661 <entry role="func_table_entry"><para role="func_signature">
17662 Function signature
17663 </para>
17664 <para>
17665 Description
17666 </para>
17667 <para>
17668 Example(s)
17669 </para></entry>
17670 </row>
17671 </thead>
17672 <tbody>
17673 <row>
17674 <entry role="func_table_entry"><para role="func_signature">
17675 <indexterm><primary>json constructor</primary></indexterm>
17676 <function>json</function> (
17677 <parameter>expression</parameter>
17678 <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional></optional>
17679 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional></optional>
17680 <optional> <literal>RETURNING</literal> <replaceable>json_data_type</replaceable> </optional>)
17681 </para>
17682 <para>
17683 The <parameter>expression</parameter> can be any text type or a
17684 <type>bytea</type> in UTF8 encoding. If the
17685 <parameter>expression</parameter> is NULL, an
17686 <acronym>SQL</acronym> null value is returned.
17687 If <literal>WITH UNIQUE</literal> is specified, the
17688 <parameter>expression</parameter> must not contain any duplicate
17689 object keys.
17690 </para>
17691 <para>
17692 <literal>json('{"a":123, "b":[true,"foo"], "a":"bar"}')</literal>
17693 <returnvalue>{"a":123, "b":[true,"foo"], "a":"bar"}</returnvalue>
17694 </para>
17695 <para>
17696 <literal>json('{"a":123,"b":[true,"foo"],"a":"bar"}' returning jsonb)</literal>
17697 <returnvalue>{"a": "bar", "b": [true, "foo"]}</returnvalue>
17698 </para></entry>
17699 </row>
17700 <row>
17701 <entry role="func_table_entry"><para role="func_signature">
17702 <indexterm><primary>json_scalar</primary></indexterm>
17703 <function>json_scalar</function> (<parameter>expression</parameter>
17704 <optional> <literal>RETURNING</literal> <replaceable>json_data_type</replaceable> </optional>)
17705 </para>
17706 <para>
17707 Returns a JSON scalar value representing
17708 <parameter>expression</parameter>.
17709 If the input is NULL, an SQL NULL is returned. If the input is a number
17710 or a boolean value, a corresponding JSON number or boolean value is
17711 returned. For any other value a JSON string is returned.
17712 </para>
17713 <para>
17714 <literal>json_scalar(123.45)</literal>
17715 <returnvalue>123.45</returnvalue>
17716 </para>
17717 <para>
17718 <literal>json_scalar(CURRENT_TIMESTAMP)</literal>
17719 <returnvalue>"2022-05-10T10:51:04.62128-04:00"</returnvalue>
17720 </para></entry>
17721 </row>
17722 <row>
17723 <entry role="func_table_entry"><para role="func_signature">
17724 <indexterm><primary>json_object</primary></indexterm>
17725 <function>json_object</function> (
17726 <optional> { <parameter>key_expression</parameter> { <literal>VALUE</literal> | ':' }
17727 <parameter>value_expression</parameter> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> }<optional>, ...</optional> </optional>
17728 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
17729 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
17730 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
17731 </para>
17732 <para>
17733 Constructs a JSON object of all the key value pairs given,
17734 or an empty object if none are given.
17735 <parameter>key_expression</parameter> is a scalar expression
17736 defining the <acronym>JSON</acronym> key, which is
17737 converted to the <type>text</type> type.
17738 It cannot be <literal>NULL</literal> nor can it
17739 belong to a type that has a cast to the <type>json</type>.
17740 If <literal>WITH UNIQUE</literal> is specified, there must not
17741 be any duplicate <parameter>key_expression</parameter>.
17742 If <literal>ABSENT ON NULL</literal> is specified, the entire
17743 pair is omitted if the <parameter>value_expression</parameter>
17744 is <literal>NULL</literal>.
17745 </para>
17746 <para>
17747 <literal>json_object('code' VALUE 'P123', 'title': 'Jaws')</literal>
17748 <returnvalue>{"code" : "P123", "title" : "Jaws"}</returnvalue>
17749 </para></entry>
17750 </row>
17751 <row>
17752 <entry role="func_table_entry"><para role="func_signature">
17753 <indexterm><primary>json_objectagg</primary></indexterm>
17754 <function>json_objectagg</function> (
17755 <optional> { <parameter>key_expression</parameter> { <literal>VALUE</literal> | ':' } <parameter>value_expression</parameter> } </optional>
17756 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
17757 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
17758 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
17759 </para>
17760 <para>
17761 Behaves like <function>json_object</function> above, but as an
17762 aggregate function, so it only takes one
17763 <parameter>key_expression</parameter> and one
17764 <parameter>value_expression</parameter> parameter.
17765 </para>
17766 <para>
17767 <literal>SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date + 1)) AS t(k,v)</literal>
17768 <returnvalue>{ "a" : "2022-05-10", "b" : "2022-05-11" }</returnvalue>
17769 </para></entry>
17770 </row>
17771 <row>
17772 <entry role="func_table_entry"><para role="func_signature">
17773 <indexterm><primary>json_array</primary></indexterm>
17774 <function>json_array</function> (
17775 <optional> { <parameter>value_expression</parameter> <optional> <literal>FORMAT JSON</literal> </optional> } <optional>, ...</optional> </optional>
17776 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
17777 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
17778 </para>
17779 <para role="func_signature">
17780 <function>json_array</function> (
17781 <optional> <replaceable>query_expression</replaceable> </optional>
17782 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
17783 </para>
17784 <para>
17785 Constructs a JSON array from either a series of
17786 <parameter>value_expression</parameter> parameters or from the results
17787 of <replaceable>query_expression</replaceable>,
17788 which must be a SELECT query returning a single column. If
17789 <literal>ABSENT ON NULL</literal> is specified, NULL values are ignored.
17790 This is always the case if a
17791 <replaceable>query_expression</replaceable> is used.
17792 </para>
17793 <para>
17794 <literal>json_array(1,true,json '{"a":null}')</literal>
17795 <returnvalue>[1, true, {"a":null}]</returnvalue>
17796 </para>
17797 <para>
17798 <literal>json_array(SELECT * FROM (VALUES(1),(2)) t)</literal>
17799 <returnvalue>[1, 2]</returnvalue>
17800 </para></entry>
17801 </row>
17802 <row>
17803 <entry role="func_table_entry"><para role="func_signature">
17804 <indexterm><primary>json_arrayagg</primary></indexterm>
17805 <function>json_arrayagg</function> (
17806 <optional> <parameter>value_expression</parameter> </optional>
17807 <optional> <literal>ORDER BY</literal> <replaceable>sort_expression</replaceable> </optional>
17808 <optional> { <literal>NULL</literal> | <literal>ABSENT</literal> } <literal>ON NULL</literal> </optional>
17809 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
17810 </para>
17811 <para>
17812 Behaves in the same way as <function>json_array</function>
17813 but as an aggregate function so it only takes one
17814 <parameter>value_expression</parameter> parameter.
17815 If <literal>ABSENT ON NULL</literal> is specified, any NULL
17816 values are omitted.
17817 If <literal>ORDER BY</literal> is specified, the elements will
17818 appear in the array in that order rather than in the input order.
17819 </para>
17820 <para>
17821 <literal>SELECT json_arrayagg(v) FROM (VALUES(2),(1)) t(v)</literal>
17822 <returnvalue>[2, 1]</returnvalue>
17823 </para></entry>
17824 </row>
17825 </tbody>
17826 </tgroup>
17827 </table>
17829 <para>
17830 <xref linkend="functions-sqljson-misc" /> details SQL/JSON
17831 facilities for testing and serializing JSON.
17832 </para>
17834 <table id="functions-sqljson-misc">
17835 <title>SQL/JSON Testing and Serializing Functions</title>
17836 <tgroup cols="1">
17837 <thead>
17838 <row>
17839 <entry role="func_table_entry"><para role="func_signature">
17840 Function signature
17841 </para>
17842 <para>
17843 Description
17844 </para>
17845 <para>
17846 Example(s)
17847 </para></entry>
17848 </row>
17849 </thead>
17850 <tbody>
17851 <row>
17852 <entry role="func_table_entry"><para role="func_signature">
17853 <indexterm><primary>IS JSON</primary></indexterm>
17854 <parameter>expression</parameter> <literal>IS</literal> <optional> <literal>NOT</literal> </optional> <literal>JSON</literal>
17855 <optional> { <literal>VALUE</literal> | <literal>SCALAR</literal> | <literal>ARRAY</literal> | <literal>OBJECT</literal> } </optional>
17856 <optional> { <literal>WITH</literal> | <literal>WITHOUT</literal> } <literal>UNIQUE</literal> <optional> <literal>KEYS</literal> </optional> </optional>
17857 </para>
17858 <para>
17859 This predicate tests whether <parameter>expression</parameter> can be
17860 parsed as JSON, possibly of a specified type.
17861 If <literal>SCALAR</literal> or <literal>ARRAY</literal> or
17862 <literal>OBJECT</literal> is specified, the
17863 test is whether or not the JSON is of that particular type. If
17864 <literal>WITH UNIQUE</literal> is specified, then an any object in the
17865 <parameter>expression</parameter> is also tested to see if it
17866 has duplicate keys.
17867 </para>
17868 <para>
17869 <screen>
17870 SELECT js,
17871 js IS JSON "json?",
17872 js IS JSON SCALAR "scalar?",
17873 js IS JSON OBJECT "object?",
17874 js IS JSON ARRAY "array?"
17875 FROM
17876 (VALUES ('123'), ('"abc"'), ('{"a": "b"}'),
17877 ('[1,2]'),('abc')) foo(js);
17878 js | json? | scalar? | object? | array?
17879 ------------+-------+---------+---------+--------
17880 123 | t | t | f | f
17881 "abc" | t | t | f | f
17882 {"a": "b"} | t | f | t | f
17883 [1,2] | t | f | f | t
17884 abc | f | f | f | f
17885 </screen>
17886 </para></entry>
17887 </row>
17888 <row>
17889 <entry role="func_table_entry"><para role="func_signature">
17890 <function>json_serialize</function> (
17891 <parameter>expression</parameter> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional>
17892 <optional> <literal>RETURNING</literal> <parameter>data_type</parameter> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>)
17893 </para>
17894 <para>
17895 Transforms an SQL/JSON value into a character or binary string. The
17896 <parameter>expression</parameter> can be of any JSON type, any
17897 character string type, or <type>bytea</type> in UTF8 encoding.
17898 The returned type can be any character string type or
17899 <type>bytea</type>. The default is <type>text</type>.
17900 </para>
17901 <para>
17902 <literal>json_serialize('{ "a" : 1 } ' RETURNING bytea)</literal>
17903 <returnvalue>\x7b20226122203a2031207d20</returnvalue>
17904 </para></entry>
17905 </row>
17906 </tbody>
17907 </tgroup>
17908 </table>
17910 <para>
17911 <xref linkend="functions-sqljson-querying"/> details the SQL/JSON
17912 functions that can be used to query JSON data, except
17913 for <function>json_table</function>.
17914 </para>
17916 <note>
17917 <para>
17918 SQL/JSON paths can only be applied to the <type>jsonb</type> type, so it
17919 might be necessary to cast the <parameter>context_item</parameter>
17920 argument of these functions to <type>jsonb</type>.
17921 </para>
17922 </note>
17924 <table id="functions-sqljson-querying">
17925 <title>SQL/JSON Query Functions</title>
17926 <tgroup cols="1">
17927 <thead>
17928 <row>
17929 <entry role="func_table_entry"><para role="func_signature">
17930 Function signature
17931 </para>
17932 <para>
17933 Description
17934 </para>
17935 <para>
17936 Example(s)
17937 </para></entry>
17938 </row>
17939 </thead>
17940 <tbody>
17941 <row>
17942 <entry role="func_table_entry"><para role="func_signature">
17943 <indexterm><primary>json_exists</primary></indexterm>
17944 <function>json_exists</function> (
17945 <parameter>context_item</parameter>, <parameter>path_expression</parameter> <optional> <literal>PASSING</literal> { <parameter>value</parameter> <literal>AS</literal> <replaceable>varname</replaceable> } <optional>, ...</optional></optional>
17946 <optional> <literal>RETURNING</literal> <replaceable>data_type</replaceable> </optional>
17947 <optional> { <literal>TRUE</literal> | <literal>FALSE</literal> |<literal> UNKNOWN</literal> | <literal>ERROR</literal> } <literal>ON ERROR</literal> </optional>)
17948 </para>
17949 <para>
17950 Returns true if the SQL/JSON <parameter>path_expression</parameter>
17951 applied to the <parameter>context_item</parameter> using the
17952 <parameter>value</parameter>s yields any items.
17953 The <literal>ON ERROR</literal> clause specifies what is returned if
17954 an error occurs. Note that if the <parameter>path_expression</parameter>
17955 is <literal>strict</literal>, an error is generated if it yields no items.
17956 The default value is <literal>UNKNOWN</literal> which causes a NULL
17957 result.
17958 </para>
17959 <para>
17960 <literal>json_exists(jsonb '{"key1": [1,2,3]}', 'strict $.key1[*] ? (@ > 2)')</literal>
17961 <returnvalue>t</returnvalue>
17962 </para>
17963 <para>
17964 <literal>json_exists(jsonb '{"a": [1,2,3]}', 'lax $.a[5]' ERROR ON ERROR)</literal>
17965 <returnvalue>f</returnvalue>
17966 </para>
17967 <para>
17968 <literal>json_exists(jsonb '{"a": [1,2,3]}', 'strict $.a[5]' ERROR ON ERROR)</literal>
17969 <returnvalue>ERROR: jsonpath array subscript is out of bounds</returnvalue>
17970 </para></entry>
17971 </row>
17972 <row>
17973 <entry role="func_table_entry"><para role="func_signature">
17974 <indexterm><primary>json_value</primary></indexterm>
17975 <function>json_value</function> (
17976 <parameter>context_item</parameter>, <parameter>path_expression</parameter>
17977 <optional> <literal>PASSING</literal> { <parameter>value</parameter> <literal>AS</literal> <parameter>varname</parameter> } <optional>, ...</optional></optional>
17978 <optional> <literal>RETURNING</literal> <parameter>data_type</parameter> </optional>
17979 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>DEFAULT</literal> <parameter>expression</parameter> } <literal>ON EMPTY</literal> </optional>
17980 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>DEFAULT</literal> <parameter>expression</parameter> } <literal>ON ERROR</literal> </optional>)
17981 </para>
17982 <para>
17983 Returns the result of applying the
17984 <parameter>path_expression</parameter> to the
17985 <parameter>context_item</parameter> using the
17986 <parameter>value</parameter>s. The extracted value must be
17987 a single <acronym>SQL/JSON</acronym> scalar item. For results that
17988 are objects or arrays, use the <function>json_query</function>
17989 instead.
17990 The returned <parameter>data_type</parameter> has the same semantics
17991 as for constructor functions like <function>json_objectagg</function>.
17992 The default returned type is <type>text</type>.
17993 The <literal>ON EMPTY</literal> clause specifies the behavior if the
17994 <parameter>path_expression</parameter> yields no value at all.
17995 The <literal>ON ERROR</literal> clause specifies the behavior if an
17996 error occurs, as a result of either the evaluation or the application
17997 of the <literal>ON EMPTY</literal> clause.
17998 </para>
17999 <para>
18000 <literal>json_value(jsonb '"123.45"', '$' RETURNING float)</literal>
18001 <returnvalue>123.45</returnvalue>
18002 </para>
18003 <para>
18004 <literal>json_value(jsonb '"03:04 2015-02-01"', '$.datetime("HH24:MI&nbsp;YYYY-MM-DD")' RETURNING date)</literal>
18005 <returnvalue>2015-02-01</returnvalue>
18006 </para>
18007 <para>
18008 <literal>json_value(jsonb '[1,2]', 'strict $[*]' DEFAULT 9 ON ERROR)</literal>
18009 <returnvalue>9</returnvalue>
18010 </para></entry>
18011 </row>
18012 <row>
18013 <entry role="func_table_entry"><para role="func_signature">
18014 <indexterm><primary>json_query</primary></indexterm>
18015 <function>json_query</function> (
18016 <parameter>context_item</parameter>, <parameter>path_expression</parameter> <optional> <literal>PASSING</literal> { <parameter>value</parameter> <literal>AS</literal> <parameter>varname</parameter> } <optional>, ...</optional></optional>
18017 <optional> <literal>RETURNING</literal> <parameter>data_type</parameter> <optional> <literal>FORMAT JSON</literal> <optional> <literal>ENCODING UTF8</literal> </optional> </optional> </optional>
18018 <optional> { <literal>WITHOUT</literal> | <literal>WITH</literal> { <literal>CONDITIONAL</literal> | <optional><literal>UNCONDITIONAL</literal></optional> } } <optional> <literal>ARRAY</literal> </optional> <literal>WRAPPER</literal> </optional>
18019 <optional> { <literal>KEEP</literal> | <literal>OMIT</literal> } <literal>QUOTES</literal> <optional> <literal>ON SCALAR STRING</literal> </optional> </optional>
18020 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>EMPTY</literal> { <optional> <literal>ARRAY</literal> </optional> | <literal>OBJECT</literal> } | <literal>DEFAULT</literal> <parameter>expression</parameter> } <literal>ON EMPTY</literal> </optional>
18021 <optional> { <literal>ERROR</literal> | <literal>NULL</literal> | <literal>EMPTY</literal> { <optional> <literal>ARRAY</literal> </optional> | <literal>OBJECT</literal> } | <literal>DEFAULT</literal> <parameter>expression</parameter> } <literal>ON ERROR</literal> </optional>)
18022 </para>
18023 <para>
18024 Returns the result of applying the
18025 <parameter>path_expression</parameter> to the
18026 <parameter>context_item</parameter> using the
18027 <parameter>value</parameter>s.
18028 This function must return a JSON string, so if the path expression
18029 returns multiple SQL/JSON items, you must wrap the result using the
18030 <literal>WITH WRAPPER</literal> clause. If the wrapper is
18031 <literal>UNCONDITIONAL</literal>, an array wrapper will always
18032 be applied, even if the returned value is already a single JSON object
18033 or array, but if it is <literal>CONDITIONAL</literal> it will not be
18034 applied to a single array or object. <literal>UNCONDITIONAL</literal>
18035 is the default.
18036 If the result is a a scalar string, by default the value returned will have
18037 surrounding quotes making it a valid JSON value. However, this behavior
18038 is reversed if <literal>OMIT QUOTES</literal> is specified.
18039 The <literal>ON ERROR</literal> and <literal>ON EMPTY</literal>
18040 clauses have similar semantics to those clauses for
18041 <function>json_value</function>.
18042 The returned <parameter>data_type</parameter> has the same semantics
18043 as for constructor functions like <function>json_objectagg</function>.
18044 The default returned type is <type>text</type>.
18045 </para>
18046 <para>
18047 <literal>json_query(jsonb '[1,[2,3],null]', 'lax $[*][1]' WITH CONDITIONAL WRAPPER)</literal>
18048 <returnvalue>[3]</returnvalue>
18049 </para></entry>
18050 </row>
18051 </tbody>
18052 </tgroup>
18053 </table>
18055 </sect2>
18057 <sect2 id="functions-sqljson-table">
18058 <title>JSON_TABLE</title>
18059 <indexterm>
18060 <primary>json_table</primary>
18061 </indexterm>
18063 <para>
18064 <function>json_table</function> is an SQL/JSON function which
18065 queries <acronym>JSON</acronym> data
18066 and presents the results as a relational view, which can be accessed as a
18067 regular SQL table. You can only use <function>json_table</function> inside the
18068 <literal>FROM</literal> clause of a <literal>SELECT</literal> statement.
18069 </para>
18071 <para>
18072 Taking JSON data as input, <function>json_table</function> uses
18073 a path expression to extract a part of the provided data that
18074 will be used as a <firstterm>row pattern</firstterm> for the
18075 constructed view. Each SQL/JSON item at the top level of the row pattern serves
18076 as the source for a separate row in the constructed relational view.
18077 </para>
18079 <para>
18080 To split the row pattern into columns, <function>json_table</function>
18081 provides the <literal>COLUMNS</literal> clause that defines the
18082 schema of the created view. For each column to be constructed,
18083 this clause provides a separate path expression that evaluates
18084 the row pattern, extracts a JSON item, and returns it as a
18085 separate SQL value for the specified column. If the required value
18086 is stored in a nested level of the row pattern, it can be extracted
18087 using the <literal>NESTED PATH</literal> subclause. Joining the
18088 columns returned by <literal>NESTED PATH</literal> can add multiple
18089 new rows to the constructed view. Such rows are called
18090 <firstterm>child rows</firstterm>, as opposed to the <firstterm>parent row</firstterm>
18091 that generates them.
18092 </para>
18094 <para>
18095 The rows produced by <function>JSON_TABLE</function> are laterally
18096 joined to the row that generated them, so you do not have to explicitly join
18097 the constructed view with the original table holding <acronym>JSON</acronym>
18098 data. Optionally, you can specify how to join the columns returned
18099 by <literal>NESTED PATH</literal> using the <literal>PLAN</literal> clause.
18100 </para>
18102 <para>
18103 Each <literal>NESTED PATH</literal> clause can generate one or more
18104 columns. Columns produced by <literal>NESTED PATH</literal>s at the
18105 same level are considered to be <firstterm>siblings</firstterm>,
18106 while a column produced by a <literal>NESTED PATH</literal> is
18107 considered to be a child of the column produced by and
18108 <literal>NESTED PATH</literal> or row expression at a higher level.
18109 Sibling columns are always joined first. Once they are processed,
18110 the resulting rows are joined to the parent row.
18111 </para>
18113 <variablelist>
18114 <varlistentry>
18115 <term>
18116 <literal><parameter>context_item</parameter>, <parameter>path_expression</parameter> <optional> <literal>AS</literal> <parameter>json_path_name</parameter> </optional> <optional> <literal>PASSING</literal> { <parameter>value</parameter> <literal>AS</literal> <parameter>varname</parameter> } <optional>, ...</optional></optional></literal>
18117 </term>
18118 <listitem>
18119 <para>
18120 The input data to query, the JSON path expression defining the query,
18121 and an optional <literal>PASSING</literal> clause, which can provide data
18122 values to the <parameter>path_expression</parameter>.
18123 The result of the input data
18124 evaluation is called the <firstterm>row pattern</firstterm>. The row
18125 pattern is used as the source for row values in the constructed view.
18126 </para>
18127 </listitem>
18128 </varlistentry>
18130 <varlistentry>
18131 <term>
18132 <literal>COLUMNS</literal>( <parameter>json_table_column</parameter> <optional>, ...</optional> )
18133 </term>
18134 <listitem>
18136 <para>
18137 The <literal>COLUMNS</literal> clause defining the schema of the
18138 constructed view. In this clause, you must specify all the columns
18139 to be filled with SQL/JSON items.
18140 The <parameter>json_table_column</parameter>
18141 expression has the following syntax variants:
18142 </para>
18144 <variablelist>
18145 <varlistentry>
18146 <term>
18147 <literal><parameter>name</parameter> <parameter>type</parameter>
18148 <optional> <literal>PATH</literal> <parameter>json_path_specification</parameter> </optional></literal>
18149 </term>
18150 <listitem>
18152 <para>
18153 Inserts a single SQL/JSON item into each row of
18154 the specified column.
18155 </para>
18156 <para>
18157 The provided <literal>PATH</literal> expression parses the
18158 row pattern defined by <parameter>json_api_common_syntax</parameter>
18159 and fills the column with produced SQL/JSON items, one for each row.
18160 If the <literal>PATH</literal> expression is omitted,
18161 <function>JSON_TABLE</function> uses the
18162 <literal>$.<replaceable>name</replaceable></literal> path expression,
18163 where <replaceable>name</replaceable> is the provided column name.
18164 In this case, the column name must correspond to one of the
18165 keys within the SQL/JSON item produced by the row pattern.
18166 </para>
18167 <para>
18168 Optionally, you can add <literal>ON EMPTY</literal> and
18169 <literal>ON ERROR</literal> clauses to define how to handle missing values
18170 or structural errors.
18171 <literal>WRAPPER</literal> and <literal>QUOTES</literal> clauses can only
18172 be used with JSON, array, and composite types.
18173 These clauses have the same syntax and semantics as for
18174 <function>json_value</function> and <function>json_query</function>.
18175 </para>
18176 </listitem>
18177 </varlistentry>
18179 <varlistentry>
18180 <term>
18181 <parameter>name</parameter> <parameter>type</parameter> <literal>FORMAT</literal> <parameter>json_representation</parameter>
18182 <optional> <literal>PATH</literal> <parameter>json_path_specification</parameter> </optional>
18183 </term>
18184 <listitem>
18186 <para>
18187 Generates a column and inserts a composite SQL/JSON
18188 item into each row of this column.
18189 </para>
18190 <para>
18191 The provided <literal>PATH</literal> expression parses the
18192 row pattern defined by <parameter>json_api_common_syntax</parameter>
18193 and fills the column with produced SQL/JSON items, one for each row.
18194 If the <literal>PATH</literal> expression is omitted,
18195 <function>JSON_TABLE</function> uses the
18196 <literal>$.<parameter>name</parameter></literal> path expression,
18197 where <parameter>name</parameter> is the provided column name.
18198 In this case, the column name must correspond to one of the
18199 keys within the SQL/JSON item produced by the row pattern.
18200 </para>
18201 <para>
18202 Optionally, you can add <literal>WRAPPER</literal>, <literal>QUOTES</literal>,
18203 <literal>ON EMPTY</literal> and <literal>ON ERROR</literal> clauses
18204 to define additional settings for the returned SQL/JSON items.
18205 These clauses have the same syntax and semantics as
18206 for <function>json_query</function>.
18207 </para>
18208 </listitem>
18209 </varlistentry>
18211 <varlistentry>
18212 <term>
18213 <parameter>name</parameter> <parameter>type</parameter>
18214 <literal>EXISTS</literal> <optional> <literal>PATH</literal> <parameter>json_path_specification</parameter> </optional>
18215 </term>
18216 <listitem>
18218 <para>
18219 Generates a column and inserts a boolean item into each row of this column.
18220 </para>
18221 <para>
18222 The provided <literal>PATH</literal> expression parses the
18223 row pattern defined by <parameter>json_api_common_syntax</parameter>,
18224 checks whether any SQL/JSON items were returned, and fills the column with
18225 resulting boolean value, one for each row.
18226 The specified <parameter>type</parameter> should have cast from
18227 <type>boolean</type>.
18228 If the <literal>PATH</literal> expression is omitted,
18229 <function>JSON_TABLE</function> uses the
18230 <literal>$.<replaceable>name</replaceable></literal> path expression,
18231 where <replaceable>name</replaceable> is the provided column name.
18232 </para>
18233 <para>
18234 Optionally, you can add <literal>ON ERROR</literal> clause to define
18235 error behavior. This clause has the same syntax and semantics as
18236 for <function>json_exists</function>.
18237 </para>
18238 </listitem>
18239 </varlistentry>
18241 <varlistentry>
18242 <term>
18243 <literal>NESTED PATH</literal> <parameter>json_path_specification</parameter> <optional> <literal>AS</literal> <parameter>json_path_name</parameter> </optional>
18244 <literal>COLUMNS</literal> ( <parameter>json_table_column</parameter> <optional>, ...</optional> )
18245 </term>
18246 <listitem>
18248 <para>
18249 Extracts SQL/JSON items from nested levels of the row pattern,
18250 generates one or more columns as defined by the <literal>COLUMNS</literal>
18251 subclause, and inserts the extracted SQL/JSON items into each row of these columns.
18252 The <parameter>json_table_column</parameter> expression in the
18253 <literal>COLUMNS</literal> subclause uses the same syntax as in the
18254 parent <literal>COLUMNS</literal> clause.
18255 </para>
18257 <para>
18258 The <literal>NESTED PATH</literal> syntax is recursive,
18259 so you can go down multiple nested levels by specifying several
18260 <literal>NESTED PATH</literal> subclauses within each other.
18261 It allows to unnest the hierarchy of JSON objects and arrays
18262 in a single function invocation rather than chaining several
18263 <function>JSON_TABLE</function> expressions in an SQL statement.
18264 </para>
18266 <para>
18267 You can use the <literal>PLAN</literal> clause to define how
18268 to join the columns returned by <parameter>NESTED PATH</parameter> clauses.
18269 </para>
18270 </listitem>
18271 </varlistentry>
18273 <varlistentry>
18274 <term>
18275 <parameter>name</parameter> <literal>FOR ORDINALITY</literal>
18276 </term>
18277 <listitem>
18279 <para>
18280 Adds an ordinality column that provides sequential row numbering.
18281 You can have only one ordinality column per table. Row numbering
18282 is 1-based. For child rows that result from the <literal>NESTED PATH</literal>
18283 clauses, the parent row number is repeated.
18284 </para>
18285 </listitem>
18286 </varlistentry>
18287 </variablelist>
18289 </listitem>
18290 </varlistentry>
18292 <varlistentry>
18293 <term>
18294 <literal>AS</literal> <parameter>json_path_name</parameter>
18295 </term>
18296 <listitem>
18298 <para>
18299 The optional <parameter>json_path_name</parameter> serves as an
18300 identifier of the provided <parameter>json_path_specification</parameter>.
18301 The path name must be unique and distinct from the column names.
18302 When using the <literal>PLAN</literal> clause, you must specify the names
18303 for all the paths, including the row pattern. Each path name can appear in
18304 the <literal>PLAN</literal> clause only once.
18305 </para>
18306 </listitem>
18307 </varlistentry>
18309 <varlistentry>
18310 <term>
18311 <literal>PLAN</literal> ( <parameter>json_table_plan</parameter> )
18312 </term>
18313 <listitem>
18315 <para>
18316 Defines how to join the data returned by <literal>NESTED PATH</literal>
18317 clauses to the constructed view.
18318 </para>
18319 <para>
18320 To join columns with parent/child relationship, you can use:
18321 </para>
18322 <variablelist>
18323 <varlistentry>
18324 <term>
18325 <literal>INNER</literal>
18326 </term>
18327 <listitem>
18329 <para>
18330 Use <literal>INNER JOIN</literal>, so that the parent row
18331 is omitted from the output if it does not have any child rows
18332 after joining the data returned by <literal>NESTED PATH</literal>.
18333 </para>
18334 </listitem>
18335 </varlistentry>
18337 <varlistentry>
18338 <term>
18339 <literal>OUTER</literal>
18340 </term>
18341 <listitem>
18343 <para>
18344 Use <literal>LEFT OUTER JOIN</literal>, so that the parent row
18345 is always included into the output even if it does not have any child rows
18346 after joining the data returned by <literal>NESTED PATH</literal>, with NULL values
18347 inserted into the child columns if the corresponding
18348 values are missing.
18349 </para>
18350 <para>
18351 This is the default option for joining columns with parent/child relationship.
18352 </para>
18353 </listitem>
18354 </varlistentry>
18355 </variablelist>
18357 <para>
18358 To join sibling columns, you can use:
18359 </para>
18361 <variablelist>
18362 <varlistentry>
18363 <term>
18364 <literal>UNION</literal>
18365 </term>
18366 <listitem>
18368 <para>
18369 Generate one row for each value produced by each of the sibling
18370 columns. The columns from the other siblings are set to null.
18371 </para>
18372 <para>
18373 This is the default option for joining sibling columns.
18374 </para>
18375 </listitem>
18376 </varlistentry>
18378 <varlistentry>
18379 <term>
18380 <literal>CROSS</literal>
18381 </term>
18382 <listitem>
18384 <para>
18385 Generate one row for each combination of values from the sibling columns.
18386 </para>
18387 </listitem>
18388 </varlistentry>
18390 </variablelist>
18392 </listitem>
18393 </varlistentry>
18395 <varlistentry>
18396 <term>
18397 <literal>PLAN DEFAULT</literal> ( <replaceable>OUTER | INNER</replaceable> <optional>, <replaceable>UNION | CROSS</replaceable> </optional> )
18398 </term>
18399 <listitem>
18400 <para>
18401 The terms can also be specified in reverse order. The
18402 <literal>INNER</literal> or <literal>OUTER</literal> option defines the
18403 joining plan for parent/child columns, while <literal>UNION</literal> or
18404 <literal>CROSS</literal> affects joins of sibling columns. This form
18405 of <literal>PLAN</literal> overrides the default plan for
18406 all columns at once. Even though the path names are not included in the
18407 <literal>PLAN DEFAULT</literal> form, to conform to the SQL/JSON standard
18408 they must be provided for all the paths if the <literal>PLAN</literal>
18409 clause is used.
18410 </para>
18411 <para>
18412 <literal>PLAN DEFAULT</literal> is simpler than specifying a complete
18413 <literal>PLAN</literal>, and is often all that is required to get the desired
18414 output.
18415 </para>
18416 </listitem>
18417 </varlistentry>
18418 </variablelist>
18420 <para>Examples</para>
18422 <para>
18423 In these examples the following small table storing some JSON data will be used:
18424 <programlisting>
18425 CREATE TABLE my_films ( js jsonb );
18427 INSERT INTO my_films VALUES (
18428 '{ "favorites" : [
18429 { "kind" : "comedy", "films" : [
18430 { "title" : "Bananas",
18431 "director" : "Woody Allen"},
18432 { "title" : "The Dinner Game",
18433 "director" : "Francis Veber" } ] },
18434 { "kind" : "horror", "films" : [
18435 { "title" : "Psycho",
18436 "director" : "Alfred Hitchcock" } ] },
18437 { "kind" : "thriller", "films" : [
18438 { "title" : "Vertigo",
18439 "director" : "Alfred Hitchcock" } ] },
18440 { "kind" : "drama", "films" : [
18441 { "title" : "Yojimbo",
18442 "director" : "Akira Kurosawa" } ] }
18443 ] }');
18444 </programlisting>
18445 </para>
18446 <para>
18447 Query the <structname>my_films</structname> table holding
18448 some JSON data about the films and create a view that
18449 distributes the film genre, title, and director between separate columns:
18450 <screen>
18451 SELECT jt.* FROM
18452 my_films,
18453 JSON_TABLE ( js, '$.favorites[*]' COLUMNS (
18454 id FOR ORDINALITY,
18455 kind text PATH '$.kind',
18456 NESTED PATH '$.films[*]' COLUMNS (
18457 title text PATH '$.title',
18458 director text PATH '$.director'))) AS jt;
18459 ----+----------+------------------+-------------------
18460 id | kind | title | director
18461 ----+----------+------------------+-------------------
18462 1 | comedy | Bananas | Woody Allen
18463 1 | comedy | The Dinner Game | Francis Veber
18464 2 | horror | Psycho | Alfred Hitchcock
18465 3 | thriller | Vertigo | Alfred Hitchcock
18466 4 | drama | Yojimbo | Akira Kurosawa
18467 (5 rows)
18468 </screen>
18469 </para>
18471 <para>
18472 Find a director that has done films in two different genres:
18473 <screen>
18474 SELECT
18475 director1 AS director, title1, kind1, title2, kind2
18476 FROM
18477 my_films,
18478 JSON_TABLE ( js, '$.favorites' AS favs COLUMNS (
18479 NESTED PATH '$[*]' AS films1 COLUMNS (
18480 kind1 text PATH '$.kind',
18481 NESTED PATH '$.films[*]' AS film1 COLUMNS (
18482 title1 text PATH '$.title',
18483 director1 text PATH '$.director')
18485 NESTED PATH '$[*]' AS films2 COLUMNS (
18486 kind2 text PATH '$.kind',
18487 NESTED PATH '$.films[*]' AS film2 COLUMNS (
18488 title2 text PATH '$.title',
18489 director2 text PATH '$.director'
18493 PLAN (favs OUTER ((films1 INNER film1) CROSS (films2 INNER film2)))
18494 ) AS jt
18495 WHERE kind1 > kind2 AND director1 = director2;
18497 director | title1 | kind1 | title2 | kind2
18498 ------------------+---------+----------+--------+--------
18499 Alfred Hitchcock | Vertigo | thriller | Psycho | horror
18500 (1 row)
18501 </screen>
18502 </para>
18503 </sect2>
18505 </sect1>
18507 <sect1 id="functions-sequence">
18508 <title>Sequence Manipulation Functions</title>
18510 <indexterm>
18511 <primary>sequence</primary>
18512 </indexterm>
18514 <para>
18515 This section describes functions for operating on <firstterm>sequence
18516 objects</firstterm>, also called sequence generators or just sequences.
18517 Sequence objects are special single-row tables created with <xref
18518 linkend="sql-createsequence"/>.
18519 Sequence objects are commonly used to generate unique identifiers
18520 for rows of a table. The sequence functions, listed in <xref
18521 linkend="functions-sequence-table"/>, provide simple, multiuser-safe
18522 methods for obtaining successive sequence values from sequence
18523 objects.
18524 </para>
18526 <table id="functions-sequence-table">
18527 <title>Sequence Functions</title>
18528 <tgroup cols="1">
18529 <thead>
18530 <row>
18531 <entry role="func_table_entry"><para role="func_signature">
18532 Function
18533 </para>
18534 <para>
18535 Description
18536 </para></entry>
18537 </row>
18538 </thead>
18540 <tbody>
18541 <row>
18542 <entry role="func_table_entry"><para role="func_signature">
18543 <indexterm>
18544 <primary>nextval</primary>
18545 </indexterm>
18546 <function>nextval</function> ( <type>regclass</type> )
18547 <returnvalue>bigint</returnvalue>
18548 </para>
18549 <para>
18550 Advances the sequence object to its next value and returns that value.
18551 This is done atomically: even if multiple sessions
18552 execute <function>nextval</function> concurrently, each will safely
18553 receive a distinct sequence value.
18554 If the sequence object has been created with default parameters,
18555 successive <function>nextval</function> calls will return successive
18556 values beginning with 1. Other behaviors can be obtained by using
18557 appropriate parameters in the <xref linkend="sql-createsequence"/>
18558 command.
18559 </para>
18560 <para>
18561 This function requires <literal>USAGE</literal>
18562 or <literal>UPDATE</literal> privilege on the sequence.
18563 </para></entry>
18564 </row>
18566 <row>
18567 <entry role="func_table_entry"><para role="func_signature">
18568 <indexterm>
18569 <primary>setval</primary>
18570 </indexterm>
18571 <function>setval</function> ( <type>regclass</type>, <type>bigint</type> <optional>, <type>boolean</type> </optional> )
18572 <returnvalue>bigint</returnvalue>
18573 </para>
18574 <para>
18575 Sets the sequence object's current value, and optionally
18576 its <literal>is_called</literal> flag. The two-parameter
18577 form sets the sequence's <literal>last_value</literal> field to the
18578 specified value and sets its <literal>is_called</literal> field to
18579 <literal>true</literal>, meaning that the next
18580 <function>nextval</function> will advance the sequence before
18581 returning a value. The value that will be reported
18582 by <function>currval</function> is also set to the specified value.
18583 In the three-parameter form, <literal>is_called</literal> can be set
18584 to either <literal>true</literal>
18585 or <literal>false</literal>. <literal>true</literal> has the same
18586 effect as the two-parameter form. If it is set
18587 to <literal>false</literal>, the next <function>nextval</function>
18588 will return exactly the specified value, and sequence advancement
18589 commences with the following <function>nextval</function>.
18590 Furthermore, the value reported by <function>currval</function> is not
18591 changed in this case. For example,
18592 <programlisting>
18593 SELECT setval('myseq', 42); <lineannotation>Next <function>nextval</function> will return 43</lineannotation>
18594 SELECT setval('myseq', 42, true); <lineannotation>Same as above</lineannotation>
18595 SELECT setval('myseq', 42, false); <lineannotation>Next <function>nextval</function> will return 42</lineannotation>
18596 </programlisting>
18597 The result returned by <function>setval</function> is just the value of its
18598 second argument.
18599 </para>
18600 <para>
18601 This function requires <literal>UPDATE</literal> privilege on the
18602 sequence.
18603 </para></entry>
18604 </row>
18606 <row>
18607 <entry role="func_table_entry"><para role="func_signature">
18608 <indexterm>
18609 <primary>currval</primary>
18610 </indexterm>
18611 <function>currval</function> ( <type>regclass</type> )
18612 <returnvalue>bigint</returnvalue>
18613 </para>
18614 <para>
18615 Returns the value most recently obtained
18616 by <function>nextval</function> for this sequence in the current
18617 session. (An error is reported if <function>nextval</function> has
18618 never been called for this sequence in this session.) Because this is
18619 returning a session-local value, it gives a predictable answer whether
18620 or not other sessions have executed <function>nextval</function> since
18621 the current session did.
18622 </para>
18623 <para>
18624 This function requires <literal>USAGE</literal>
18625 or <literal>SELECT</literal> privilege on the sequence.
18626 </para></entry>
18627 </row>
18629 <row>
18630 <entry role="func_table_entry"><para role="func_signature">
18631 <indexterm>
18632 <primary>lastval</primary>
18633 </indexterm>
18634 <function>lastval</function> ()
18635 <returnvalue>bigint</returnvalue>
18636 </para>
18637 <para>
18638 Returns the value most recently returned by
18639 <function>nextval</function> in the current session. This function is
18640 identical to <function>currval</function>, except that instead
18641 of taking the sequence name as an argument it refers to whichever
18642 sequence <function>nextval</function> was most recently applied to
18643 in the current session. It is an error to call
18644 <function>lastval</function> if <function>nextval</function>
18645 has not yet been called in the current session.
18646 </para>
18647 <para>
18648 This function requires <literal>USAGE</literal>
18649 or <literal>SELECT</literal> privilege on the last used sequence.
18650 </para></entry>
18651 </row>
18652 </tbody>
18653 </tgroup>
18654 </table>
18656 <caution>
18657 <para>
18658 To avoid blocking concurrent transactions that obtain numbers from
18659 the same sequence, the value obtained by <function>nextval</function>
18660 is not reclaimed for re-use if the calling transaction later aborts.
18661 This means that transaction aborts or database crashes can result in
18662 gaps in the sequence of assigned values. That can happen without a
18663 transaction abort, too. For example an <command>INSERT</command> with
18664 an <literal>ON CONFLICT</literal> clause will compute the to-be-inserted
18665 tuple, including doing any required <function>nextval</function>
18666 calls, before detecting any conflict that would cause it to follow
18667 the <literal>ON CONFLICT</literal> rule instead.
18668 Thus, <productname>PostgreSQL</productname> sequence
18669 objects <emphasis>cannot be used to obtain <quote>gapless</quote>
18670 sequences</emphasis>.
18671 </para>
18673 <para>
18674 Likewise, sequence state changes made by <function>setval</function>
18675 are immediately visible to other transactions, and are not undone if
18676 the calling transaction rolls back.
18677 </para>
18679 <para>
18680 If the database cluster crashes before committing a transaction
18681 containing a <function>nextval</function>
18682 or <function>setval</function> call, the sequence state change might
18683 not have made its way to persistent storage, so that it is uncertain
18684 whether the sequence will have its original or updated state after the
18685 cluster restarts. This is harmless for usage of the sequence within
18686 the database, since other effects of uncommitted transactions will not
18687 be visible either. However, if you wish to use a sequence value for
18688 persistent outside-the-database purposes, make sure that the
18689 <function>nextval</function> call has been committed before doing so.
18690 </para>
18691 </caution>
18693 <para>
18694 The sequence to be operated on by a sequence function is specified by
18695 a <type>regclass</type> argument, which is simply the OID of the sequence in the
18696 <structname>pg_class</structname> system catalog. You do not have to look up the
18697 OID by hand, however, since the <type>regclass</type> data type's input
18698 converter will do the work for you. See <xref linkend="datatype-oid"/>
18699 for details.
18700 </para>
18701 </sect1>
18704 <sect1 id="functions-conditional">
18705 <title>Conditional Expressions</title>
18707 <indexterm>
18708 <primary>CASE</primary>
18709 </indexterm>
18711 <indexterm>
18712 <primary>conditional expression</primary>
18713 </indexterm>
18715 <para>
18716 This section describes the <acronym>SQL</acronym>-compliant conditional expressions
18717 available in <productname>PostgreSQL</productname>.
18718 </para>
18720 <tip>
18721 <para>
18722 If your needs go beyond the capabilities of these conditional
18723 expressions, you might want to consider writing a server-side function
18724 in a more expressive programming language.
18725 </para>
18726 </tip>
18728 <note>
18729 <para>
18730 Although <token>COALESCE</token>, <token>GREATEST</token>, and
18731 <token>LEAST</token> are syntactically similar to functions, they are
18732 not ordinary functions, and thus cannot be used with explicit
18733 <token>VARIADIC</token> array arguments.
18734 </para>
18735 </note>
18737 <sect2 id="functions-case">
18738 <title><literal>CASE</literal></title>
18740 <para>
18741 The <acronym>SQL</acronym> <token>CASE</token> expression is a
18742 generic conditional expression, similar to if/else statements in
18743 other programming languages:
18745 <synopsis>
18746 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
18747 <optional>WHEN ...</optional>
18748 <optional>ELSE <replaceable>result</replaceable></optional>
18750 </synopsis>
18752 <token>CASE</token> clauses can be used wherever
18753 an expression is valid. Each <replaceable>condition</replaceable> is an
18754 expression that returns a <type>boolean</type> result. If the condition's
18755 result is true, the value of the <token>CASE</token> expression is the
18756 <replaceable>result</replaceable> that follows the condition, and the
18757 remainder of the <token>CASE</token> expression is not processed. If the
18758 condition's result is not true, any subsequent <token>WHEN</token> clauses
18759 are examined in the same manner. If no <token>WHEN</token>
18760 <replaceable>condition</replaceable> yields true, the value of the
18761 <token>CASE</token> expression is the <replaceable>result</replaceable> of the
18762 <token>ELSE</token> clause. If the <token>ELSE</token> clause is
18763 omitted and no condition is true, the result is null.
18764 </para>
18766 <para>
18767 An example:
18768 <screen>
18769 SELECT * FROM test;
18778 SELECT a,
18779 CASE WHEN a=1 THEN 'one'
18780 WHEN a=2 THEN 'two'
18781 ELSE 'other'
18783 FROM test;
18785 a | case
18786 ---+-------
18787 1 | one
18788 2 | two
18789 3 | other
18790 </screen>
18791 </para>
18793 <para>
18794 The data types of all the <replaceable>result</replaceable>
18795 expressions must be convertible to a single output type.
18796 See <xref linkend="typeconv-union-case"/> for more details.
18797 </para>
18799 <para>
18800 There is a <quote>simple</quote> form of <token>CASE</token> expression
18801 that is a variant of the general form above:
18803 <synopsis>
18804 CASE <replaceable>expression</replaceable>
18805 WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
18806 <optional>WHEN ...</optional>
18807 <optional>ELSE <replaceable>result</replaceable></optional>
18809 </synopsis>
18811 The first
18812 <replaceable>expression</replaceable> is computed, then compared to
18813 each of the <replaceable>value</replaceable> expressions in the
18814 <token>WHEN</token> clauses until one is found that is equal to it. If
18815 no match is found, the <replaceable>result</replaceable> of the
18816 <token>ELSE</token> clause (or a null value) is returned. This is similar
18817 to the <function>switch</function> statement in C.
18818 </para>
18820 <para>
18821 The example above can be written using the simple
18822 <token>CASE</token> syntax:
18823 <screen>
18824 SELECT a,
18825 CASE a WHEN 1 THEN 'one'
18826 WHEN 2 THEN 'two'
18827 ELSE 'other'
18829 FROM test;
18831 a | case
18832 ---+-------
18833 1 | one
18834 2 | two
18835 3 | other
18836 </screen>
18837 </para>
18839 <para>
18840 A <token>CASE</token> expression does not evaluate any subexpressions
18841 that are not needed to determine the result. For example, this is a
18842 possible way of avoiding a division-by-zero failure:
18843 <programlisting>
18844 SELECT ... WHERE CASE WHEN x &lt;&gt; 0 THEN y/x &gt; 1.5 ELSE false END;
18845 </programlisting>
18846 </para>
18848 <note>
18849 <para>
18850 As described in <xref linkend="syntax-express-eval"/>, there are various
18851 situations in which subexpressions of an expression are evaluated at
18852 different times, so that the principle that <quote><token>CASE</token>
18853 evaluates only necessary subexpressions</quote> is not ironclad. For
18854 example a constant <literal>1/0</literal> subexpression will usually result in
18855 a division-by-zero failure at planning time, even if it's within
18856 a <token>CASE</token> arm that would never be entered at run time.
18857 </para>
18858 </note>
18859 </sect2>
18861 <sect2 id="functions-coalesce-nvl-ifnull">
18862 <title><literal>COALESCE</literal></title>
18864 <indexterm>
18865 <primary>COALESCE</primary>
18866 </indexterm>
18868 <indexterm>
18869 <primary>NVL</primary>
18870 </indexterm>
18872 <indexterm>
18873 <primary>IFNULL</primary>
18874 </indexterm>
18876 <synopsis>
18877 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18878 </synopsis>
18880 <para>
18881 The <function>COALESCE</function> function returns the first of its
18882 arguments that is not null. Null is returned only if all arguments
18883 are null. It is often used to substitute a default value for
18884 null values when data is retrieved for display, for example:
18885 <programlisting>
18886 SELECT COALESCE(description, short_description, '(none)') ...
18887 </programlisting>
18888 This returns <varname>description</varname> if it is not null, otherwise
18889 <varname>short_description</varname> if it is not null, otherwise <literal>(none)</literal>.
18890 </para>
18892 <para>
18893 The arguments must all be convertible to a common data type, which
18894 will be the type of the result (see
18895 <xref linkend="typeconv-union-case"/> for details).
18896 </para>
18898 <para>
18899 Like a <token>CASE</token> expression, <function>COALESCE</function> only
18900 evaluates the arguments that are needed to determine the result;
18901 that is, arguments to the right of the first non-null argument are
18902 not evaluated. This SQL-standard function provides capabilities similar
18903 to <function>NVL</function> and <function>IFNULL</function>, which are used in some other
18904 database systems.
18905 </para>
18906 </sect2>
18908 <sect2 id="functions-nullif">
18909 <title><literal>NULLIF</literal></title>
18911 <indexterm>
18912 <primary>NULLIF</primary>
18913 </indexterm>
18915 <synopsis>
18916 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
18917 </synopsis>
18919 <para>
18920 The <function>NULLIF</function> function returns a null value if
18921 <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
18922 otherwise it returns <replaceable>value1</replaceable>.
18923 This can be used to perform the inverse operation of the
18924 <function>COALESCE</function> example given above:
18925 <programlisting>
18926 SELECT NULLIF(value, '(none)') ...
18927 </programlisting>
18928 In this example, if <literal>value</literal> is <literal>(none)</literal>,
18929 null is returned, otherwise the value of <literal>value</literal>
18930 is returned.
18931 </para>
18933 <para>
18934 The two arguments must be of comparable types.
18935 To be specific, they are compared exactly as if you had
18936 written <literal><replaceable>value1</replaceable>
18937 = <replaceable>value2</replaceable></literal>, so there must be a
18938 suitable <literal>=</literal> operator available.
18939 </para>
18941 <para>
18942 The result has the same type as the first argument &mdash; but there is
18943 a subtlety. What is actually returned is the first argument of the
18944 implied <literal>=</literal> operator, and in some cases that will have
18945 been promoted to match the second argument's type. For
18946 example, <literal>NULLIF(1, 2.2)</literal> yields <type>numeric</type>,
18947 because there is no <type>integer</type> <literal>=</literal>
18948 <type>numeric</type> operator,
18949 only <type>numeric</type> <literal>=</literal> <type>numeric</type>.
18950 </para>
18952 </sect2>
18954 <sect2 id="functions-greatest-least">
18955 <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
18957 <indexterm>
18958 <primary>GREATEST</primary>
18959 </indexterm>
18960 <indexterm>
18961 <primary>LEAST</primary>
18962 </indexterm>
18964 <synopsis>
18965 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18966 </synopsis>
18967 <synopsis>
18968 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
18969 </synopsis>
18971 <para>
18972 The <function>GREATEST</function> and <function>LEAST</function> functions select the
18973 largest or smallest value from a list of any number of expressions.
18974 The expressions must all be convertible to a common data type, which
18975 will be the type of the result
18976 (see <xref linkend="typeconv-union-case"/> for details). NULL values
18977 in the list are ignored. The result will be NULL only if all the
18978 expressions evaluate to NULL.
18979 </para>
18981 <para>
18982 Note that <function>GREATEST</function> and <function>LEAST</function> are not in
18983 the SQL standard, but are a common extension. Some other databases
18984 make them return NULL if any argument is NULL, rather than only when
18985 all are NULL.
18986 </para>
18987 </sect2>
18988 </sect1>
18990 <sect1 id="functions-array">
18991 <title>Array Functions and Operators</title>
18993 <para>
18994 <xref linkend="array-operators-table"/> shows the specialized operators
18995 available for array types.
18996 In addition to those, the usual comparison operators shown in <xref
18997 linkend="functions-comparison-op-table"/> are available for
18998 arrays. The comparison operators compare the array contents
18999 element-by-element, using the default B-tree comparison function for
19000 the element data type, and sort based on the first difference.
19001 In multidimensional arrays the elements are visited in row-major order
19002 (last subscript varies most rapidly).
19003 If the contents of two arrays are equal but the dimensionality is
19004 different, the first difference in the dimensionality information
19005 determines the sort order.
19006 </para>
19008 <table id="array-operators-table">
19009 <title>Array Operators</title>
19010 <tgroup cols="1">
19011 <thead>
19012 <row>
19013 <entry role="func_table_entry"><para role="func_signature">
19014 Operator
19015 </para>
19016 <para>
19017 Description
19018 </para>
19019 <para>
19020 Example(s)
19021 </para></entry>
19022 </row>
19023 </thead>
19025 <tbody>
19026 <row>
19027 <entry role="func_table_entry"><para role="func_signature">
19028 <type>anyarray</type> <literal>@&gt;</literal> <type>anyarray</type>
19029 <returnvalue>boolean</returnvalue>
19030 </para>
19031 <para>
19032 Does the first array contain the second, that is, does each element
19033 appearing in the second array equal some element of the first array?
19034 (Duplicates are not treated specially,
19035 thus <literal>ARRAY[1]</literal> and <literal>ARRAY[1,1]</literal> are
19036 each considered to contain the other.)
19037 </para>
19038 <para>
19039 <literal>ARRAY[1,4,3] @&gt; ARRAY[3,1,3]</literal>
19040 <returnvalue>t</returnvalue>
19041 </para></entry>
19042 </row>
19044 <row>
19045 <entry role="func_table_entry"><para role="func_signature">
19046 <type>anyarray</type> <literal>&lt;@</literal> <type>anyarray</type>
19047 <returnvalue>boolean</returnvalue>
19048 </para>
19049 <para>
19050 Is the first array contained by the second?
19051 </para>
19052 <para>
19053 <literal>ARRAY[2,2,7] &lt;@ ARRAY[1,7,4,2,6]</literal>
19054 <returnvalue>t</returnvalue>
19055 </para></entry>
19056 </row>
19058 <row>
19059 <entry role="func_table_entry"><para role="func_signature">
19060 <type>anyarray</type> <literal>&amp;&amp;</literal> <type>anyarray</type>
19061 <returnvalue>boolean</returnvalue>
19062 </para>
19063 <para>
19064 Do the arrays overlap, that is, have any elements in common?
19065 </para>
19066 <para>
19067 <literal>ARRAY[1,4,3] &amp;&amp; ARRAY[2,1]</literal>
19068 <returnvalue>t</returnvalue>
19069 </para></entry>
19070 </row>
19072 <row>
19073 <entry role="func_table_entry"><para role="func_signature">
19074 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
19075 <returnvalue>anycompatiblearray</returnvalue>
19076 </para>
19077 <para>
19078 Concatenates the two arrays. Concatenating a null or empty array is a
19079 no-op; otherwise the arrays must have the same number of dimensions
19080 (as illustrated by the first example) or differ in number of
19081 dimensions by one (as illustrated by the second).
19082 If the arrays are not of identical element types, they will be coerced
19083 to a common type (see <xref linkend="typeconv-union-case"/>).
19084 </para>
19085 <para>
19086 <literal>ARRAY[1,2,3] || ARRAY[4,5,6,7]</literal>
19087 <returnvalue>{1,2,3,4,5,6,7}</returnvalue>
19088 </para>
19089 <para>
19090 <literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9.9]]</literal>
19091 <returnvalue>{{1,2,3},{4,5,6},{7,8,9.9}}</returnvalue>
19092 </para></entry>
19093 </row>
19095 <row>
19096 <entry role="func_table_entry"><para role="func_signature">
19097 <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
19098 <returnvalue>anycompatiblearray</returnvalue>
19099 </para>
19100 <para>
19101 Concatenates an element onto the front of an array (which must be
19102 empty or one-dimensional).
19103 </para>
19104 <para>
19105 <literal>3 || ARRAY[4,5,6]</literal>
19106 <returnvalue>{3,4,5,6}</returnvalue>
19107 </para></entry>
19108 </row>
19110 <row>
19111 <entry role="func_table_entry"><para role="func_signature">
19112 <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
19113 <returnvalue>anycompatiblearray</returnvalue>
19114 </para>
19115 <para>
19116 Concatenates an element onto the end of an array (which must be
19117 empty or one-dimensional).
19118 </para>
19119 <para>
19120 <literal>ARRAY[4,5,6] || 7</literal>
19121 <returnvalue>{4,5,6,7}</returnvalue>
19122 </para></entry>
19123 </row>
19124 </tbody>
19125 </tgroup>
19126 </table>
19128 <para>
19129 See <xref linkend="arrays"/> for more details about array operator
19130 behavior. See <xref linkend="indexes-types"/> for more details about
19131 which operators support indexed operations.
19132 </para>
19134 <para>
19135 <xref linkend="array-functions-table"/> shows the functions
19136 available for use with array types. See <xref linkend="arrays"/>
19137 for more information and examples of the use of these functions.
19138 </para>
19140 <table id="array-functions-table">
19141 <title>Array Functions</title>
19142 <tgroup cols="1">
19143 <thead>
19144 <row>
19145 <entry role="func_table_entry"><para role="func_signature">
19146 Function
19147 </para>
19148 <para>
19149 Description
19150 </para>
19151 <para>
19152 Example(s)
19153 </para></entry>
19154 </row>
19155 </thead>
19157 <tbody>
19158 <row>
19159 <entry role="func_table_entry"><para role="func_signature">
19160 <indexterm>
19161 <primary>array_append</primary>
19162 </indexterm>
19163 <function>array_append</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
19164 <returnvalue>anycompatiblearray</returnvalue>
19165 </para>
19166 <para>
19167 Appends an element to the end of an array (same as
19168 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatible</type>
19169 operator).
19170 </para>
19171 <para>
19172 <literal>array_append(ARRAY[1,2], 3)</literal>
19173 <returnvalue>{1,2,3}</returnvalue>
19174 </para></entry>
19175 </row>
19177 <row>
19178 <entry role="func_table_entry"><para role="func_signature">
19179 <indexterm>
19180 <primary>array_cat</primary>
19181 </indexterm>
19182 <function>array_cat</function> ( <type>anycompatiblearray</type>, <type>anycompatiblearray</type> )
19183 <returnvalue>anycompatiblearray</returnvalue>
19184 </para>
19185 <para>
19186 Concatenates two arrays (same as
19187 the <type>anycompatiblearray</type> <literal>||</literal> <type>anycompatiblearray</type>
19188 operator).
19189 </para>
19190 <para>
19191 <literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal>
19192 <returnvalue>{1,2,3,4,5}</returnvalue>
19193 </para></entry>
19194 </row>
19196 <row>
19197 <entry role="func_table_entry"><para role="func_signature">
19198 <indexterm>
19199 <primary>array_dims</primary>
19200 </indexterm>
19201 <function>array_dims</function> ( <type>anyarray</type> )
19202 <returnvalue>text</returnvalue>
19203 </para>
19204 <para>
19205 Returns a text representation of the array's dimensions.
19206 </para>
19207 <para>
19208 <literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal>
19209 <returnvalue>[1:2][1:3]</returnvalue>
19210 </para></entry>
19211 </row>
19213 <row>
19214 <entry role="func_table_entry"><para role="func_signature">
19215 <indexterm>
19216 <primary>array_fill</primary>
19217 </indexterm>
19218 <function>array_fill</function> ( <type>anyelement</type>, <type>integer[]</type>
19219 <optional>, <type>integer[]</type> </optional> )
19220 <returnvalue>anyarray</returnvalue>
19221 </para>
19222 <para>
19223 Returns an array filled with copies of the given value, having
19224 dimensions of the lengths specified by the second argument.
19225 The optional third argument supplies lower-bound values for each
19226 dimension (which default to all <literal>1</literal>).
19227 </para>
19228 <para>
19229 <literal>array_fill(11, ARRAY[2,3])</literal>
19230 <returnvalue>{{11,11,11},{11,11,11}}</returnvalue>
19231 </para>
19232 <para>
19233 <literal>array_fill(7, ARRAY[3], ARRAY[2])</literal>
19234 <returnvalue>[2:4]={7,7,7}</returnvalue>
19235 </para></entry>
19236 </row>
19238 <row>
19239 <entry role="func_table_entry"><para role="func_signature">
19240 <indexterm>
19241 <primary>array_length</primary>
19242 </indexterm>
19243 <function>array_length</function> ( <type>anyarray</type>, <type>integer</type> )
19244 <returnvalue>integer</returnvalue>
19245 </para>
19246 <para>
19247 Returns the length of the requested array dimension.
19248 (Produces NULL instead of 0 for empty or missing array dimensions.)
19249 </para>
19250 <para>
19251 <literal>array_length(array[1,2,3], 1)</literal>
19252 <returnvalue>3</returnvalue>
19253 </para>
19254 <para>
19255 <literal>array_length(array[]::int[], 1)</literal>
19256 <returnvalue>NULL</returnvalue>
19257 </para>
19258 <para>
19259 <literal>array_length(array['text'], 2)</literal>
19260 <returnvalue>NULL</returnvalue>
19261 </para></entry>
19262 </row>
19264 <row>
19265 <entry role="func_table_entry"><para role="func_signature">
19266 <indexterm>
19267 <primary>array_lower</primary>
19268 </indexterm>
19269 <function>array_lower</function> ( <type>anyarray</type>, <type>integer</type> )
19270 <returnvalue>integer</returnvalue>
19271 </para>
19272 <para>
19273 Returns the lower bound of the requested array dimension.
19274 </para>
19275 <para>
19276 <literal>array_lower('[0:2]={1,2,3}'::integer[], 1)</literal>
19277 <returnvalue>0</returnvalue>
19278 </para></entry>
19279 </row>
19281 <row>
19282 <entry role="func_table_entry"><para role="func_signature">
19283 <indexterm>
19284 <primary>array_ndims</primary>
19285 </indexterm>
19286 <function>array_ndims</function> ( <type>anyarray</type> )
19287 <returnvalue>integer</returnvalue>
19288 </para>
19289 <para>
19290 Returns the number of dimensions of the array.
19291 </para>
19292 <para>
19293 <literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal>
19294 <returnvalue>2</returnvalue>
19295 </para></entry>
19296 </row>
19298 <row>
19299 <entry role="func_table_entry"><para role="func_signature">
19300 <indexterm>
19301 <primary>array_position</primary>
19302 </indexterm>
19303 <function>array_position</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> <optional>, <type>integer</type> </optional> )
19304 <returnvalue>integer</returnvalue>
19305 </para>
19306 <para>
19307 Returns the subscript of the first occurrence of the second argument
19308 in the array, or <literal>NULL</literal> if it's not present.
19309 If the third argument is given, the search begins at that subscript.
19310 The array must be one-dimensional.
19311 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
19312 semantics, so it is possible to search for <literal>NULL</literal>.
19313 </para>
19314 <para>
19315 <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')</literal>
19316 <returnvalue>2</returnvalue>
19317 </para></entry>
19318 </row>
19320 <row>
19321 <entry role="func_table_entry"><para role="func_signature">
19322 <indexterm>
19323 <primary>array_positions</primary>
19324 </indexterm>
19325 <function>array_positions</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
19326 <returnvalue>integer[]</returnvalue>
19327 </para>
19328 <para>
19329 Returns an array of the subscripts of all occurrences of the second
19330 argument in the array given as first argument.
19331 The array must be one-dimensional.
19332 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
19333 semantics, so it is possible to search for <literal>NULL</literal>.
19334 <literal>NULL</literal> is returned only if the array
19335 is <literal>NULL</literal>; if the value is not found in the array, an
19336 empty array is returned.
19337 </para>
19338 <para>
19339 <literal>array_positions(ARRAY['A','A','B','A'], 'A')</literal>
19340 <returnvalue>{1,2,4}</returnvalue>
19341 </para></entry>
19342 </row>
19344 <row>
19345 <entry role="func_table_entry"><para role="func_signature">
19346 <indexterm>
19347 <primary>array_prepend</primary>
19348 </indexterm>
19349 <function>array_prepend</function> ( <type>anycompatible</type>, <type>anycompatiblearray</type> )
19350 <returnvalue>anycompatiblearray</returnvalue>
19351 </para>
19352 <para>
19353 Prepends an element to the beginning of an array (same as
19354 the <type>anycompatible</type> <literal>||</literal> <type>anycompatiblearray</type>
19355 operator).
19356 </para>
19357 <para>
19358 <literal>array_prepend(1, ARRAY[2,3])</literal>
19359 <returnvalue>{1,2,3}</returnvalue>
19360 </para></entry>
19361 </row>
19363 <row>
19364 <entry role="func_table_entry"><para role="func_signature">
19365 <indexterm>
19366 <primary>array_remove</primary>
19367 </indexterm>
19368 <function>array_remove</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type> )
19369 <returnvalue>anycompatiblearray</returnvalue>
19370 </para>
19371 <para>
19372 Removes all elements equal to the given value from the array.
19373 The array must be one-dimensional.
19374 Comparisons are done using <literal>IS NOT DISTINCT FROM</literal>
19375 semantics, so it is possible to remove <literal>NULL</literal>s.
19376 </para>
19377 <para>
19378 <literal>array_remove(ARRAY[1,2,3,2], 2)</literal>
19379 <returnvalue>{1,3}</returnvalue>
19380 </para></entry>
19381 </row>
19383 <row>
19384 <entry role="func_table_entry"><para role="func_signature">
19385 <indexterm>
19386 <primary>array_replace</primary>
19387 </indexterm>
19388 <function>array_replace</function> ( <type>anycompatiblearray</type>, <type>anycompatible</type>, <type>anycompatible</type> )
19389 <returnvalue>anycompatiblearray</returnvalue>
19390 </para>
19391 <para>
19392 Replaces each array element equal to the second argument with the
19393 third argument.
19394 </para>
19395 <para>
19396 <literal>array_replace(ARRAY[1,2,5,4], 5, 3)</literal>
19397 <returnvalue>{1,2,3,4}</returnvalue>
19398 </para></entry>
19399 </row>
19401 <row>
19402 <entry role="func_table_entry"><para role="func_signature">
19403 <indexterm id="function-array-to-string">
19404 <primary>array_to_string</primary>
19405 </indexterm>
19406 <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> )
19407 <returnvalue>text</returnvalue>
19408 </para>
19409 <para>
19410 Converts each array element to its text representation, and
19411 concatenates those separated by
19412 the <parameter>delimiter</parameter> string.
19413 If <parameter>null_string</parameter> is given and is
19414 not <literal>NULL</literal>, then <literal>NULL</literal> array
19415 entries are represented by that string; otherwise, they are omitted.
19416 See also <link linkend="function-string-to-array"><function>string_to_array</function></link>.
19417 </para>
19418 <para>
19419 <literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal>
19420 <returnvalue>1,2,3,*,5</returnvalue>
19421 </para></entry>
19422 </row>
19424 <row>
19425 <entry role="func_table_entry"><para role="func_signature">
19426 <indexterm>
19427 <primary>array_upper</primary>
19428 </indexterm>
19429 <function>array_upper</function> ( <type>anyarray</type>, <type>integer</type> )
19430 <returnvalue>integer</returnvalue>
19431 </para>
19432 <para>
19433 Returns the upper bound of the requested array dimension.
19434 </para>
19435 <para>
19436 <literal>array_upper(ARRAY[1,8,3,7], 1)</literal>
19437 <returnvalue>4</returnvalue>
19438 </para></entry>
19439 </row>
19441 <row>
19442 <entry role="func_table_entry"><para role="func_signature">
19443 <indexterm>
19444 <primary>cardinality</primary>
19445 </indexterm>
19446 <function>cardinality</function> ( <type>anyarray</type> )
19447 <returnvalue>integer</returnvalue>
19448 </para>
19449 <para>
19450 Returns the total number of elements in the array, or 0 if the array
19451 is empty.
19452 </para>
19453 <para>
19454 <literal>cardinality(ARRAY[[1,2],[3,4]])</literal>
19455 <returnvalue>4</returnvalue>
19456 </para></entry>
19457 </row>
19459 <row>
19460 <entry role="func_table_entry"><para role="func_signature">
19461 <indexterm>
19462 <primary>trim_array</primary>
19463 </indexterm>
19464 <function>trim_array</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>n</parameter> <type>integer</type> )
19465 <returnvalue>anyarray</returnvalue>
19466 </para>
19467 <para>
19468 Trims an array by removing the last <parameter>n</parameter> elements.
19469 If the array is multidimensional, only the first dimension is trimmed.
19470 </para>
19471 <para>
19472 <literal>trim_array(ARRAY[1,2,3,4,5,6], 2)</literal>
19473 <returnvalue>{1,2,3,4}</returnvalue>
19474 </para></entry>
19475 </row>
19477 <row>
19478 <entry role="func_table_entry"><para role="func_signature">
19479 <indexterm>
19480 <primary>unnest</primary>
19481 </indexterm>
19482 <function>unnest</function> ( <type>anyarray</type> )
19483 <returnvalue>setof anyelement</returnvalue>
19484 </para>
19485 <para>
19486 Expands an array into a set of rows.
19487 The array's elements are read out in storage order.
19488 </para>
19489 <para>
19490 <literal>unnest(ARRAY[1,2])</literal>
19491 <returnvalue></returnvalue>
19492 <programlisting>
19495 </programlisting>
19496 </para>
19497 <para>
19498 <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])</literal>
19499 <returnvalue></returnvalue>
19500 <programlisting>
19504 quux
19505 </programlisting>
19506 </para></entry>
19507 </row>
19509 <row>
19510 <entry role="func_table_entry"><para role="func_signature">
19511 <function>unnest</function> ( <type>anyarray</type>, <type>anyarray</type> <optional>, ... </optional> )
19512 <returnvalue>setof anyelement, anyelement [, ... ]</returnvalue>
19513 </para>
19514 <para>
19515 Expands multiple arrays (possibly of different data types) into a set of
19516 rows. If the arrays are not all the same length then the shorter ones
19517 are padded with <literal>NULL</literal>s. This form is only allowed
19518 in a query's FROM clause; see <xref linkend="queries-tablefunctions"/>.
19519 </para>
19520 <para>
19521 <literal>select * from unnest(ARRAY[1,2], ARRAY['foo','bar','baz']) as x(a,b)</literal>
19522 <returnvalue></returnvalue>
19523 <programlisting>
19524 a | b
19525 ---+-----
19526 1 | foo
19527 2 | bar
19528 | baz
19529 </programlisting>
19530 </para></entry>
19531 </row>
19532 </tbody>
19533 </tgroup>
19534 </table>
19536 <para>
19537 See also <xref linkend="functions-aggregate"/> about the aggregate
19538 function <function>array_agg</function> for use with arrays.
19539 </para>
19540 </sect1>
19542 <sect1 id="functions-range">
19543 <title>Range/Multirange Functions and Operators</title>
19545 <para>
19546 See <xref linkend="rangetypes"/> for an overview of range types.
19547 </para>
19549 <para>
19550 <xref linkend="range-operators-table"/> shows the specialized operators
19551 available for range types.
19552 <xref linkend="multirange-operators-table"/> shows the specialized operators
19553 available for multirange types.
19554 In addition to those, the usual comparison operators shown in
19555 <xref linkend="functions-comparison-op-table"/> are available for range
19556 and multirange types. The comparison operators order first by the range lower
19557 bounds, and only if those are equal do they compare the upper bounds. The
19558 multirange operators compare each range until one is unequal. This
19559 does not usually result in a useful overall ordering, but the operators are
19560 provided to allow unique indexes to be constructed on ranges.
19561 </para>
19563 <table id="range-operators-table">
19564 <title>Range Operators</title>
19565 <tgroup cols="1">
19566 <thead>
19567 <row>
19568 <entry role="func_table_entry"><para role="func_signature">
19569 Operator
19570 </para>
19571 <para>
19572 Description
19573 </para>
19574 <para>
19575 Example(s)
19576 </para></entry>
19577 </row>
19578 </thead>
19580 <tbody>
19581 <row>
19582 <entry role="func_table_entry"><para role="func_signature">
19583 <type>anyrange</type> <literal>@&gt;</literal> <type>anyrange</type>
19584 <returnvalue>boolean</returnvalue>
19585 </para>
19586 <para>
19587 Does the first range contain the second?
19588 </para>
19589 <para>
19590 <literal>int4range(2,4) @&gt; int4range(2,3)</literal>
19591 <returnvalue>t</returnvalue>
19592 </para></entry>
19593 </row>
19595 <row>
19596 <entry role="func_table_entry"><para role="func_signature">
19597 <type>anyrange</type> <literal>@&gt;</literal> <type>anyelement</type>
19598 <returnvalue>boolean</returnvalue>
19599 </para>
19600 <para>
19601 Does the range contain the element?
19602 </para>
19603 <para>
19604 <literal>'[2011-01-01,2011-03-01)'::tsrange @&gt; '2011-01-10'::timestamp</literal>
19605 <returnvalue>t</returnvalue>
19606 </para></entry>
19607 </row>
19609 <row>
19610 <entry role="func_table_entry"><para role="func_signature">
19611 <type>anyrange</type> <literal>&lt;@</literal> <type>anyrange</type>
19612 <returnvalue>boolean</returnvalue>
19613 </para>
19614 <para>
19615 Is the first range contained by the second?
19616 </para>
19617 <para>
19618 <literal>int4range(2,4) &lt;@ int4range(1,7)</literal>
19619 <returnvalue>t</returnvalue>
19620 </para></entry>
19621 </row>
19623 <row>
19624 <entry role="func_table_entry"><para role="func_signature">
19625 <type>anyelement</type> <literal>&lt;@</literal> <type>anyrange</type>
19626 <returnvalue>boolean</returnvalue>
19627 </para>
19628 <para>
19629 Is the element contained in the range?
19630 </para>
19631 <para>
19632 <literal>42 &lt;@ int4range(1,7)</literal>
19633 <returnvalue>f</returnvalue>
19634 </para></entry>
19635 </row>
19637 <row>
19638 <entry role="func_table_entry"><para role="func_signature">
19639 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
19640 <returnvalue>boolean</returnvalue>
19641 </para>
19642 <para>
19643 Do the ranges overlap, that is, have any elements in common?
19644 </para>
19645 <para>
19646 <literal>int8range(3,7) &amp;&amp; int8range(4,12)</literal>
19647 <returnvalue>t</returnvalue>
19648 </para></entry>
19649 </row>
19651 <row>
19652 <entry role="func_table_entry"><para role="func_signature">
19653 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
19654 <returnvalue>boolean</returnvalue>
19655 </para>
19656 <para>
19657 Is the first range strictly left of the second?
19658 </para>
19659 <para>
19660 <literal>int8range(1,10) &lt;&lt; int8range(100,110)</literal>
19661 <returnvalue>t</returnvalue>
19662 </para></entry>
19663 </row>
19665 <row>
19666 <entry role="func_table_entry"><para role="func_signature">
19667 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
19668 <returnvalue>boolean</returnvalue>
19669 </para>
19670 <para>
19671 Is the first range strictly right of the second?
19672 </para>
19673 <para>
19674 <literal>int8range(50,60) &gt;&gt; int8range(20,30)</literal>
19675 <returnvalue>t</returnvalue>
19676 </para></entry>
19677 </row>
19679 <row>
19680 <entry role="func_table_entry"><para role="func_signature">
19681 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
19682 <returnvalue>boolean</returnvalue>
19683 </para>
19684 <para>
19685 Does the first range not extend to the right of the second?
19686 </para>
19687 <para>
19688 <literal>int8range(1,20) &amp;&lt; int8range(18,20)</literal>
19689 <returnvalue>t</returnvalue>
19690 </para></entry>
19691 </row>
19693 <row>
19694 <entry role="func_table_entry"><para role="func_signature">
19695 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
19696 <returnvalue>boolean</returnvalue>
19697 </para>
19698 <para>
19699 Does the first range not extend to the left of the second?
19700 </para>
19701 <para>
19702 <literal>int8range(7,20) &amp;&gt; int8range(5,10)</literal>
19703 <returnvalue>t</returnvalue>
19704 </para></entry>
19705 </row>
19707 <row>
19708 <entry role="func_table_entry"><para role="func_signature">
19709 <type>anyrange</type> <literal>-|-</literal> <type>anyrange</type>
19710 <returnvalue>boolean</returnvalue>
19711 </para>
19712 <para>
19713 Are the ranges adjacent?
19714 </para>
19715 <para>
19716 <literal>numrange(1.1,2.2) -|- numrange(2.2,3.3)</literal>
19717 <returnvalue>t</returnvalue>
19718 </para></entry>
19719 </row>
19721 <row>
19722 <entry role="func_table_entry"><para role="func_signature">
19723 <type>anyrange</type> <literal>+</literal> <type>anyrange</type>
19724 <returnvalue>anyrange</returnvalue>
19725 </para>
19726 <para>
19727 Computes the union of the ranges. The ranges must overlap or be
19728 adjacent, so that the union is a single range (but
19729 see <function>range_merge()</function>).
19730 </para>
19731 <para>
19732 <literal>numrange(5,15) + numrange(10,20)</literal>
19733 <returnvalue>[5,20)</returnvalue>
19734 </para></entry>
19735 </row>
19737 <row>
19738 <entry role="func_table_entry"><para role="func_signature">
19739 <type>anyrange</type> <literal>*</literal> <type>anyrange</type>
19740 <returnvalue>anyrange</returnvalue>
19741 </para>
19742 <para>
19743 Computes the intersection of the ranges.
19744 </para>
19745 <para>
19746 <literal>int8range(5,15) * int8range(10,20)</literal>
19747 <returnvalue>[10,15)</returnvalue>
19748 </para></entry>
19749 </row>
19751 <row>
19752 <entry role="func_table_entry"><para role="func_signature">
19753 <type>anyrange</type> <literal>-</literal> <type>anyrange</type>
19754 <returnvalue>anyrange</returnvalue>
19755 </para>
19756 <para>
19757 Computes the difference of the ranges. The second range must not be
19758 contained in the first in such a way that the difference would not be
19759 a single range.
19760 </para>
19761 <para>
19762 <literal>int8range(5,15) - int8range(10,20)</literal>
19763 <returnvalue>[5,10)</returnvalue>
19764 </para></entry>
19765 </row>
19766 </tbody>
19767 </tgroup>
19768 </table>
19770 <table id="multirange-operators-table">
19771 <title>Multirange Operators</title>
19772 <tgroup cols="1">
19773 <thead>
19774 <row>
19775 <entry role="func_table_entry"><para role="func_signature">
19776 Operator
19777 </para>
19778 <para>
19779 Description
19780 </para>
19781 <para>
19782 Example(s)
19783 </para></entry>
19784 </row>
19785 </thead>
19787 <tbody>
19788 <row>
19789 <entry role="func_table_entry"><para role="func_signature">
19790 <type>anymultirange</type> <literal>@&gt;</literal> <type>anymultirange</type>
19791 <returnvalue>boolean</returnvalue>
19792 </para>
19793 <para>
19794 Does the first multirange contain the second?
19795 </para>
19796 <para>
19797 <literal>'{[2,4)}'::int4multirange @&gt; '{[2,3)}'::int4multirange</literal>
19798 <returnvalue>t</returnvalue>
19799 </para></entry>
19800 </row>
19802 <row>
19803 <entry role="func_table_entry"><para role="func_signature">
19804 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyrange</type>
19805 <returnvalue>boolean</returnvalue>
19806 </para>
19807 <para>
19808 Does the multirange contain the range?
19809 </para>
19810 <para>
19811 <literal>'{[2,4)}'::int4multirange @&gt; int4range(2,3)</literal>
19812 <returnvalue>t</returnvalue>
19813 </para></entry>
19814 </row>
19816 <row>
19817 <entry role="func_table_entry"><para role="func_signature">
19818 <type>anymultirange</type> <literal>@&gt;</literal> <type>anyelement</type>
19819 <returnvalue>boolean</returnvalue>
19820 </para>
19821 <para>
19822 Does the multirange contain the element?
19823 </para>
19824 <para>
19825 <literal>'{[2011-01-01,2011-03-01)}'::tsmultirange @&gt; '2011-01-10'::timestamp</literal>
19826 <returnvalue>t</returnvalue>
19827 </para></entry>
19828 </row>
19830 <row>
19831 <entry role="func_table_entry"><para role="func_signature">
19832 <type>anyrange</type> <literal>@&gt;</literal> <type>anymultirange</type>
19833 <returnvalue>boolean</returnvalue>
19834 </para>
19835 <para>
19836 Does the range contain the multirange?
19837 </para>
19838 <para>
19839 <literal>'[2,4)'::int4range @&gt; '{[2,3)}'::int4multirange</literal>
19840 <returnvalue>t</returnvalue>
19841 </para></entry>
19842 </row>
19844 <row>
19845 <entry role="func_table_entry"><para role="func_signature">
19846 <type>anymultirange</type> <literal>&lt;@</literal> <type>anymultirange</type>
19847 <returnvalue>boolean</returnvalue>
19848 </para>
19849 <para>
19850 Is the first multirange contained by the second?
19851 </para>
19852 <para>
19853 <literal>'{[2,4)}'::int4multirange &lt;@ '{[1,7)}'::int4multirange</literal>
19854 <returnvalue>t</returnvalue>
19855 </para></entry>
19856 </row>
19858 <row>
19859 <entry role="func_table_entry"><para role="func_signature">
19860 <type>anymultirange</type> <literal>&lt;@</literal> <type>anyrange</type>
19861 <returnvalue>boolean</returnvalue>
19862 </para>
19863 <para>
19864 Is the multirange contained by the range?
19865 </para>
19866 <para>
19867 <literal>'{[2,4)}'::int4multirange &lt;@ int4range(1,7)</literal>
19868 <returnvalue>t</returnvalue>
19869 </para></entry>
19870 </row>
19872 <row>
19873 <entry role="func_table_entry"><para role="func_signature">
19874 <type>anyrange</type> <literal>&lt;@</literal> <type>anymultirange</type>
19875 <returnvalue>boolean</returnvalue>
19876 </para>
19877 <para>
19878 Is the range contained by the multirange?
19879 </para>
19880 <para>
19881 <literal>int4range(2,4) &lt;@ '{[1,7)}'::int4multirange</literal>
19882 <returnvalue>t</returnvalue>
19883 </para></entry>
19884 </row>
19886 <row>
19887 <entry role="func_table_entry"><para role="func_signature">
19888 <type>anyelement</type> <literal>&lt;@</literal> <type>anymultirange</type>
19889 <returnvalue>boolean</returnvalue>
19890 </para>
19891 <para>
19892 Is the element contained by the multirange?
19893 </para>
19894 <para>
19895 <literal>4 &lt;@ '{[1,7)}'::int4multirange</literal>
19896 <returnvalue>t</returnvalue>
19897 </para></entry>
19898 </row>
19900 <row>
19901 <entry role="func_table_entry"><para role="func_signature">
19902 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
19903 <returnvalue>boolean</returnvalue>
19904 </para>
19905 <para>
19906 Do the multiranges overlap, that is, have any elements in common?
19907 </para>
19908 <para>
19909 <literal>'{[3,7)}'::int8multirange &amp;&amp; '{[4,12)}'::int8multirange</literal>
19910 <returnvalue>t</returnvalue>
19911 </para></entry>
19912 </row>
19914 <row>
19915 <entry role="func_table_entry"><para role="func_signature">
19916 <type>anymultirange</type> <literal>&amp;&amp;</literal> <type>anyrange</type>
19917 <returnvalue>boolean</returnvalue>
19918 </para>
19919 <para>
19920 Does the multirange overlap the range?
19921 </para>
19922 <para>
19923 <literal>'{[3,7)}'::int8multirange &amp;&amp; int8range(4,12)</literal>
19924 <returnvalue>t</returnvalue>
19925 </para></entry>
19926 </row>
19928 <row>
19929 <entry role="func_table_entry"><para role="func_signature">
19930 <type>anyrange</type> <literal>&amp;&amp;</literal> <type>anymultirange</type>
19931 <returnvalue>boolean</returnvalue>
19932 </para>
19933 <para>
19934 Does the range overlap the multirange?
19935 </para>
19936 <para>
19937 <literal>int8range(3,7) &amp;&amp; '{[4,12)}'::int8multirange</literal>
19938 <returnvalue>t</returnvalue>
19939 </para></entry>
19940 </row>
19942 <row>
19943 <entry role="func_table_entry"><para role="func_signature">
19944 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
19945 <returnvalue>boolean</returnvalue>
19946 </para>
19947 <para>
19948 Is the first multirange strictly left of the second?
19949 </para>
19950 <para>
19951 <literal>'{[1,10)}'::int8multirange &lt;&lt; '{[100,110)}'::int8multirange</literal>
19952 <returnvalue>t</returnvalue>
19953 </para></entry>
19954 </row>
19956 <row>
19957 <entry role="func_table_entry"><para role="func_signature">
19958 <type>anymultirange</type> <literal>&lt;&lt;</literal> <type>anyrange</type>
19959 <returnvalue>boolean</returnvalue>
19960 </para>
19961 <para>
19962 Is the multirange strictly left of the range?
19963 </para>
19964 <para>
19965 <literal>'{[1,10)}'::int8multirange &lt;&lt; int8range(100,110)</literal>
19966 <returnvalue>t</returnvalue>
19967 </para></entry>
19968 </row>
19970 <row>
19971 <entry role="func_table_entry"><para role="func_signature">
19972 <type>anyrange</type> <literal>&lt;&lt;</literal> <type>anymultirange</type>
19973 <returnvalue>boolean</returnvalue>
19974 </para>
19975 <para>
19976 Is the range strictly left of the multirange?
19977 </para>
19978 <para>
19979 <literal>int8range(1,10) &lt;&lt; '{[100,110)}'::int8multirange</literal>
19980 <returnvalue>t</returnvalue>
19981 </para></entry>
19982 </row>
19984 <row>
19985 <entry role="func_table_entry"><para role="func_signature">
19986 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
19987 <returnvalue>boolean</returnvalue>
19988 </para>
19989 <para>
19990 Is the first multirange strictly right of the second?
19991 </para>
19992 <para>
19993 <literal>'{[50,60)}'::int8multirange &gt;&gt; '{[20,30)}'::int8multirange</literal>
19994 <returnvalue>t</returnvalue>
19995 </para></entry>
19996 </row>
19998 <row>
19999 <entry role="func_table_entry"><para role="func_signature">
20000 <type>anymultirange</type> <literal>&gt;&gt;</literal> <type>anyrange</type>
20001 <returnvalue>boolean</returnvalue>
20002 </para>
20003 <para>
20004 Is the multirange strictly right of the range?
20005 </para>
20006 <para>
20007 <literal>'{[50,60)}'::int8multirange &gt;&gt; int8range(20,30)</literal>
20008 <returnvalue>t</returnvalue>
20009 </para></entry>
20010 </row>
20012 <row>
20013 <entry role="func_table_entry"><para role="func_signature">
20014 <type>anyrange</type> <literal>&gt;&gt;</literal> <type>anymultirange</type>
20015 <returnvalue>boolean</returnvalue>
20016 </para>
20017 <para>
20018 Is the range strictly right of the multirange?
20019 </para>
20020 <para>
20021 <literal>int8range(50,60) &gt;&gt; '{[20,30)}'::int8multirange</literal>
20022 <returnvalue>t</returnvalue>
20023 </para></entry>
20024 </row>
20026 <row>
20027 <entry role="func_table_entry"><para role="func_signature">
20028 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
20029 <returnvalue>boolean</returnvalue>
20030 </para>
20031 <para>
20032 Does the first multirange not extend to the right of the second?
20033 </para>
20034 <para>
20035 <literal>'{[1,20)}'::int8multirange &amp;&lt; '{[18,20)}'::int8multirange</literal>
20036 <returnvalue>t</returnvalue>
20037 </para></entry>
20038 </row>
20040 <row>
20041 <entry role="func_table_entry"><para role="func_signature">
20042 <type>anymultirange</type> <literal>&amp;&lt;</literal> <type>anyrange</type>
20043 <returnvalue>boolean</returnvalue>
20044 </para>
20045 <para>
20046 Does the multirange not extend to the right of the range?
20047 </para>
20048 <para>
20049 <literal>'{[1,20)}'::int8multirange &amp;&lt; int8range(18,20)</literal>
20050 <returnvalue>t</returnvalue>
20051 </para></entry>
20052 </row>
20054 <row>
20055 <entry role="func_table_entry"><para role="func_signature">
20056 <type>anyrange</type> <literal>&amp;&lt;</literal> <type>anymultirange</type>
20057 <returnvalue>boolean</returnvalue>
20058 </para>
20059 <para>
20060 Does the range not extend to the right of the multirange?
20061 </para>
20062 <para>
20063 <literal>int8range(1,20) &amp;&lt; '{[18,20)}'::int8multirange</literal>
20064 <returnvalue>t</returnvalue>
20065 </para></entry>
20066 </row>
20068 <row>
20069 <entry role="func_table_entry"><para role="func_signature">
20070 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
20071 <returnvalue>boolean</returnvalue>
20072 </para>
20073 <para>
20074 Does the first multirange not extend to the left of the second?
20075 </para>
20076 <para>
20077 <literal>'{[7,20)}'::int8multirange &amp;&gt; '{[5,10)}'::int8multirange</literal>
20078 <returnvalue>t</returnvalue>
20079 </para></entry>
20080 </row>
20082 <row>
20083 <entry role="func_table_entry"><para role="func_signature">
20084 <type>anymultirange</type> <literal>&amp;&gt;</literal> <type>anyrange</type>
20085 <returnvalue>boolean</returnvalue>
20086 </para>
20087 <para>
20088 Does the multirange not extend to the left of the range?
20089 </para>
20090 <para>
20091 <literal>'{[7,20)}'::int8multirange &amp;&gt; int8range(5,10)</literal>
20092 <returnvalue>t</returnvalue>
20093 </para></entry>
20094 </row>
20096 <row>
20097 <entry role="func_table_entry"><para role="func_signature">
20098 <type>anyrange</type> <literal>&amp;&gt;</literal> <type>anymultirange</type>
20099 <returnvalue>boolean</returnvalue>
20100 </para>
20101 <para>
20102 Does the range not extend to the left of the multirange?
20103 </para>
20104 <para>
20105 <literal>int8range(7,20) &amp;&gt; '{[5,10)}'::int8multirange</literal>
20106 <returnvalue>t</returnvalue>
20107 </para></entry>
20108 </row>
20110 <row>
20111 <entry role="func_table_entry"><para role="func_signature">
20112 <type>anymultirange</type> <literal>-|-</literal> <type>anymultirange</type>
20113 <returnvalue>boolean</returnvalue>
20114 </para>
20115 <para>
20116 Are the multiranges adjacent?
20117 </para>
20118 <para>
20119 <literal>'{[1.1,2.2)}'::nummultirange -|- '{[2.2,3.3)}'::nummultirange</literal>
20120 <returnvalue>t</returnvalue>
20121 </para></entry>
20122 </row>
20124 <row>
20125 <entry role="func_table_entry"><para role="func_signature">
20126 <type>anymultirange</type> <literal>-|-</literal> <type>anyrange</type>
20127 <returnvalue>boolean</returnvalue>
20128 </para>
20129 <para>
20130 Is the multirange adjacent to the range?
20131 </para>
20132 <para>
20133 <literal>'{[1.1,2.2)}'::nummultirange -|- numrange(2.2,3.3)</literal>
20134 <returnvalue>t</returnvalue>
20135 </para></entry>
20136 </row>
20138 <row>
20139 <entry role="func_table_entry"><para role="func_signature">
20140 <type>anyrange</type> <literal>-|-</literal> <type>anymultirange</type>
20141 <returnvalue>boolean</returnvalue>
20142 </para>
20143 <para>
20144 Is the range adjacent to the multirange?
20145 </para>
20146 <para>
20147 <literal>numrange(1.1,2.2) -|- '{[2.2,3.3)}'::nummultirange</literal>
20148 <returnvalue>t</returnvalue>
20149 </para></entry>
20150 </row>
20152 <row>
20153 <entry role="func_table_entry"><para role="func_signature">
20154 <type>anymultirange</type> <literal>+</literal> <type>anymultirange</type>
20155 <returnvalue>anymultirange</returnvalue>
20156 </para>
20157 <para>
20158 Computes the union of the multiranges. The multiranges need not overlap
20159 or be adjacent.
20160 </para>
20161 <para>
20162 <literal>'{[5,10)}'::nummultirange + '{[15,20)}'::nummultirange</literal>
20163 <returnvalue>{[5,10), [15,20)}</returnvalue>
20164 </para></entry>
20165 </row>
20167 <row>
20168 <entry role="func_table_entry"><para role="func_signature">
20169 <type>anymultirange</type> <literal>*</literal> <type>anymultirange</type>
20170 <returnvalue>anymultirange</returnvalue>
20171 </para>
20172 <para>
20173 Computes the intersection of the multiranges.
20174 </para>
20175 <para>
20176 <literal>'{[5,15)}'::int8multirange * '{[10,20)}'::int8multirange</literal>
20177 <returnvalue>{[10,15)}</returnvalue>
20178 </para></entry>
20179 </row>
20181 <row>
20182 <entry role="func_table_entry"><para role="func_signature">
20183 <type>anymultirange</type> <literal>-</literal> <type>anymultirange</type>
20184 <returnvalue>anymultirange</returnvalue>
20185 </para>
20186 <para>
20187 Computes the difference of the multiranges.
20188 </para>
20189 <para>
20190 <literal>'{[5,20)}'::int8multirange - '{[10,15)}'::int8multirange</literal>
20191 <returnvalue>{[5,10), [15,20)}</returnvalue>
20192 </para></entry>
20193 </row>
20194 </tbody>
20195 </tgroup>
20196 </table>
20198 <para>
20199 The left-of/right-of/adjacent operators always return false when an empty
20200 range or multirange is involved; that is, an empty range is not considered to
20201 be either before or after any other range.
20202 </para>
20204 <para>
20205 Elsewhere empty ranges and multiranges are treated as the additive identity:
20206 anything unioned with an empty value is itself. Anything minus an empty
20207 value is itself. An empty multirange has exactly the same points as an empty
20208 range. Every range contains the empty range. Every multirange contains as many
20209 empty ranges as you like.
20210 </para>
20212 <para>
20213 The range union and difference operators will fail if the resulting range would
20214 need to contain two disjoint sub-ranges, as such a range cannot be
20215 represented. There are separate operators for union and difference that take
20216 multirange parameters and return a multirange, and they do not fail even if
20217 their arguments are disjoint. So if you need a union or difference operation
20218 for ranges that may be disjoint, you can avoid errors by first casting your
20219 ranges to multiranges.
20220 </para>
20222 <para>
20223 <xref linkend="range-functions-table"/> shows the functions
20224 available for use with range types.
20225 <xref linkend="multirange-functions-table"/> shows the functions
20226 available for use with multirange types.
20227 </para>
20229 <table id="range-functions-table">
20230 <title>Range Functions</title>
20231 <tgroup cols="1">
20232 <thead>
20233 <row>
20234 <entry role="func_table_entry"><para role="func_signature">
20235 Function
20236 </para>
20237 <para>
20238 Description
20239 </para>
20240 <para>
20241 Example(s)
20242 </para></entry>
20243 </row>
20244 </thead>
20246 <tbody>
20247 <row>
20248 <entry role="func_table_entry"><para role="func_signature">
20249 <indexterm>
20250 <primary>lower</primary>
20251 </indexterm>
20252 <function>lower</function> ( <type>anyrange</type> )
20253 <returnvalue>anyelement</returnvalue>
20254 </para>
20255 <para>
20256 Extracts the lower bound of the range (<literal>NULL</literal> if the
20257 range is empty or the lower bound is infinite).
20258 </para>
20259 <para>
20260 <literal>lower(numrange(1.1,2.2))</literal>
20261 <returnvalue>1.1</returnvalue>
20262 </para></entry>
20263 </row>
20265 <row>
20266 <entry role="func_table_entry"><para role="func_signature">
20267 <indexterm>
20268 <primary>upper</primary>
20269 </indexterm>
20270 <function>upper</function> ( <type>anyrange</type> )
20271 <returnvalue>anyelement</returnvalue>
20272 </para>
20273 <para>
20274 Extracts the upper bound of the range (<literal>NULL</literal> if the
20275 range is empty or the upper bound is infinite).
20276 </para>
20277 <para>
20278 <literal>upper(numrange(1.1,2.2))</literal>
20279 <returnvalue>2.2</returnvalue>
20280 </para></entry>
20281 </row>
20283 <row>
20284 <entry role="func_table_entry"><para role="func_signature">
20285 <indexterm>
20286 <primary>isempty</primary>
20287 </indexterm>
20288 <function>isempty</function> ( <type>anyrange</type> )
20289 <returnvalue>boolean</returnvalue>
20290 </para>
20291 <para>
20292 Is the range empty?
20293 </para>
20294 <para>
20295 <literal>isempty(numrange(1.1,2.2))</literal>
20296 <returnvalue>f</returnvalue>
20297 </para></entry>
20298 </row>
20300 <row>
20301 <entry role="func_table_entry"><para role="func_signature">
20302 <indexterm>
20303 <primary>lower_inc</primary>
20304 </indexterm>
20305 <function>lower_inc</function> ( <type>anyrange</type> )
20306 <returnvalue>boolean</returnvalue>
20307 </para>
20308 <para>
20309 Is the range's lower bound inclusive?
20310 </para>
20311 <para>
20312 <literal>lower_inc(numrange(1.1,2.2))</literal>
20313 <returnvalue>t</returnvalue>
20314 </para></entry>
20315 </row>
20317 <row>
20318 <entry role="func_table_entry"><para role="func_signature">
20319 <indexterm>
20320 <primary>upper_inc</primary>
20321 </indexterm>
20322 <function>upper_inc</function> ( <type>anyrange</type> )
20323 <returnvalue>boolean</returnvalue>
20324 </para>
20325 <para>
20326 Is the range's upper bound inclusive?
20327 </para>
20328 <para>
20329 <literal>upper_inc(numrange(1.1,2.2))</literal>
20330 <returnvalue>f</returnvalue>
20331 </para></entry>
20332 </row>
20334 <row>
20335 <entry role="func_table_entry"><para role="func_signature">
20336 <indexterm>
20337 <primary>lower_inf</primary>
20338 </indexterm>
20339 <function>lower_inf</function> ( <type>anyrange</type> )
20340 <returnvalue>boolean</returnvalue>
20341 </para>
20342 <para>
20343 Is the range's lower bound infinite?
20344 </para>
20345 <para>
20346 <literal>lower_inf('(,)'::daterange)</literal>
20347 <returnvalue>t</returnvalue>
20348 </para></entry>
20349 </row>
20351 <row>
20352 <entry role="func_table_entry"><para role="func_signature">
20353 <indexterm>
20354 <primary>upper_inf</primary>
20355 </indexterm>
20356 <function>upper_inf</function> ( <type>anyrange</type> )
20357 <returnvalue>boolean</returnvalue>
20358 </para>
20359 <para>
20360 Is the range's upper bound infinite?
20361 </para>
20362 <para>
20363 <literal>upper_inf('(,)'::daterange)</literal>
20364 <returnvalue>t</returnvalue>
20365 </para></entry>
20366 </row>
20368 <row>
20369 <entry role="func_table_entry"><para role="func_signature">
20370 <indexterm>
20371 <primary>range_merge</primary>
20372 </indexterm>
20373 <function>range_merge</function> ( <type>anyrange</type>, <type>anyrange</type> )
20374 <returnvalue>anyrange</returnvalue>
20375 </para>
20376 <para>
20377 Computes the smallest range that includes both of the given ranges.
20378 </para>
20379 <para>
20380 <literal>range_merge('[1,2)'::int4range, '[3,4)'::int4range)</literal>
20381 <returnvalue>[1,4)</returnvalue>
20382 </para></entry>
20383 </row>
20384 </tbody>
20385 </tgroup>
20386 </table>
20388 <table id="multirange-functions-table">
20389 <title>Multirange Functions</title>
20390 <tgroup cols="1">
20391 <thead>
20392 <row>
20393 <entry role="func_table_entry"><para role="func_signature">
20394 Function
20395 </para>
20396 <para>
20397 Description
20398 </para>
20399 <para>
20400 Example(s)
20401 </para></entry>
20402 </row>
20403 </thead>
20404 <tbody>
20405 <row>
20406 <entry role="func_table_entry"><para role="func_signature">
20407 <indexterm>
20408 <primary>lower</primary>
20409 </indexterm>
20410 <function>lower</function> ( <type>anymultirange</type> )
20411 <returnvalue>anyelement</returnvalue>
20412 </para>
20413 <para>
20414 Extracts the lower bound of the multirange (<literal>NULL</literal> if the
20415 multirange is empty or the lower bound is infinite).
20416 </para>
20417 <para>
20418 <literal>lower('{[1.1,2.2)}'::nummultirange)</literal>
20419 <returnvalue>1.1</returnvalue>
20420 </para></entry>
20421 </row>
20423 <row>
20424 <entry role="func_table_entry"><para role="func_signature">
20425 <indexterm>
20426 <primary>upper</primary>
20427 </indexterm>
20428 <function>upper</function> ( <type>anymultirange</type> )
20429 <returnvalue>anyelement</returnvalue>
20430 </para>
20431 <para>
20432 Extracts the upper bound of the multirange (<literal>NULL</literal> if the
20433 multirange is empty or the upper bound is infinite).
20434 </para>
20435 <para>
20436 <literal>upper('{[1.1,2.2)}'::nummultirange)</literal>
20437 <returnvalue>2.2</returnvalue>
20438 </para></entry>
20439 </row>
20441 <row>
20442 <entry role="func_table_entry"><para role="func_signature">
20443 <indexterm>
20444 <primary>isempty</primary>
20445 </indexterm>
20446 <function>isempty</function> ( <type>anymultirange</type> )
20447 <returnvalue>boolean</returnvalue>
20448 </para>
20449 <para>
20450 Is the multirange empty?
20451 </para>
20452 <para>
20453 <literal>isempty('{[1.1,2.2)}'::nummultirange)</literal>
20454 <returnvalue>f</returnvalue>
20455 </para></entry>
20456 </row>
20458 <row>
20459 <entry role="func_table_entry"><para role="func_signature">
20460 <indexterm>
20461 <primary>lower_inc</primary>
20462 </indexterm>
20463 <function>lower_inc</function> ( <type>anymultirange</type> )
20464 <returnvalue>boolean</returnvalue>
20465 </para>
20466 <para>
20467 Is the multirange's lower bound inclusive?
20468 </para>
20469 <para>
20470 <literal>lower_inc('{[1.1,2.2)}'::nummultirange)</literal>
20471 <returnvalue>t</returnvalue>
20472 </para></entry>
20473 </row>
20475 <row>
20476 <entry role="func_table_entry"><para role="func_signature">
20477 <indexterm>
20478 <primary>upper_inc</primary>
20479 </indexterm>
20480 <function>upper_inc</function> ( <type>anymultirange</type> )
20481 <returnvalue>boolean</returnvalue>
20482 </para>
20483 <para>
20484 Is the multirange's upper bound inclusive?
20485 </para>
20486 <para>
20487 <literal>upper_inc('{[1.1,2.2)}'::nummultirange)</literal>
20488 <returnvalue>f</returnvalue>
20489 </para></entry>
20490 </row>
20492 <row>
20493 <entry role="func_table_entry"><para role="func_signature">
20494 <indexterm>
20495 <primary>lower_inf</primary>
20496 </indexterm>
20497 <function>lower_inf</function> ( <type>anymultirange</type> )
20498 <returnvalue>boolean</returnvalue>
20499 </para>
20500 <para>
20501 Is the multirange's lower bound infinite?
20502 </para>
20503 <para>
20504 <literal>lower_inf('{(,)}'::datemultirange)</literal>
20505 <returnvalue>t</returnvalue>
20506 </para></entry>
20507 </row>
20509 <row>
20510 <entry role="func_table_entry"><para role="func_signature">
20511 <indexterm>
20512 <primary>upper_inf</primary>
20513 </indexterm>
20514 <function>upper_inf</function> ( <type>anymultirange</type> )
20515 <returnvalue>boolean</returnvalue>
20516 </para>
20517 <para>
20518 Is the multirange's upper bound infinite?
20519 </para>
20520 <para>
20521 <literal>upper_inf('{(,)}'::datemultirange)</literal>
20522 <returnvalue>t</returnvalue>
20523 </para></entry>
20524 </row>
20526 <row>
20527 <entry role="func_table_entry"><para role="func_signature">
20528 <indexterm>
20529 <primary>range_merge</primary>
20530 </indexterm>
20531 <function>range_merge</function> ( <type>anymultirange</type> )
20532 <returnvalue>anyrange</returnvalue>
20533 </para>
20534 <para>
20535 Computes the smallest range that includes the entire multirange.
20536 </para>
20537 <para>
20538 <literal>range_merge('{[1,2), [3,4)}'::int4multirange)</literal>
20539 <returnvalue>[1,4)</returnvalue>
20540 </para></entry>
20541 </row>
20543 <row>
20544 <entry role="func_table_entry"><para role="func_signature">
20545 <indexterm>
20546 <primary>multirange (function)</primary>
20547 </indexterm>
20548 <function>multirange</function> ( <type>anyrange</type> )
20549 <returnvalue>anymultirange</returnvalue>
20550 </para>
20551 <para>
20552 Returns a multirange containing just the given range.
20553 </para>
20554 <para>
20555 <literal>multirange('[1,2)'::int4range)</literal>
20556 <returnvalue>{[1,2)}</returnvalue>
20557 </para></entry>
20558 </row>
20560 <row>
20561 <entry role="func_table_entry"><para role="func_signature">
20562 <indexterm>
20563 <primary>unnest</primary>
20564 <secondary>for multirange</secondary>
20565 </indexterm>
20566 <function>unnest</function> ( <type>anymultirange</type> )
20567 <returnvalue>setof anyrange</returnvalue>
20568 </para>
20569 <para>
20570 Expands a multirange into a set of ranges.
20571 The ranges are read out in storage order (ascending).
20572 </para>
20573 <para>
20574 <literal>unnest('{[1,2), [3,4)}'::int4multirange)</literal>
20575 <returnvalue></returnvalue>
20576 <programlisting>
20577 [1,2)
20578 [3,4)
20579 </programlisting>
20580 </para></entry>
20581 </row>
20582 </tbody>
20583 </tgroup>
20584 </table>
20586 <para>
20587 The <function>lower_inc</function>, <function>upper_inc</function>,
20588 <function>lower_inf</function>, and <function>upper_inf</function>
20589 functions all return false for an empty range or multirange.
20590 </para>
20591 </sect1>
20593 <sect1 id="functions-aggregate">
20594 <title>Aggregate Functions</title>
20596 <indexterm zone="functions-aggregate">
20597 <primary>aggregate function</primary>
20598 <secondary>built-in</secondary>
20599 </indexterm>
20601 <para>
20602 <firstterm>Aggregate functions</firstterm> compute a single result
20603 from a set of input values. The built-in general-purpose aggregate
20604 functions are listed in <xref linkend="functions-aggregate-table"/>
20605 while statistical aggregates are in <xref
20606 linkend="functions-aggregate-statistics-table"/>.
20607 The built-in within-group ordered-set aggregate functions
20608 are listed in <xref linkend="functions-orderedset-table"/>
20609 while the built-in within-group hypothetical-set ones are in <xref
20610 linkend="functions-hypothetical-table"/>. Grouping operations,
20611 which are closely related to aggregate functions, are listed in
20612 <xref linkend="functions-grouping-table"/>.
20613 The special syntax considerations for aggregate
20614 functions are explained in <xref linkend="syntax-aggregates"/>.
20615 Consult <xref linkend="tutorial-agg"/> for additional introductory
20616 information.
20617 </para>
20619 <para>
20620 Aggregate functions that support <firstterm>Partial Mode</firstterm>
20621 are eligible to participate in various optimizations, such as parallel
20622 aggregation.
20623 </para>
20625 <table id="functions-aggregate-table">
20626 <title>General-Purpose Aggregate Functions</title>
20627 <tgroup cols="2">
20628 <colspec colname="col1" colwidth="10*"/>
20629 <colspec colname="col2" colwidth="1*"/>
20630 <thead>
20631 <row>
20632 <entry role="func_table_entry"><para role="func_signature">
20633 Function
20634 </para>
20635 <para>
20636 Description
20637 </para></entry>
20638 <entry>Partial Mode</entry>
20639 </row>
20640 </thead>
20642 <tbody>
20643 <row>
20644 <entry role="func_table_entry"><para role="func_signature">
20645 <indexterm>
20646 <primary>array_agg</primary>
20647 </indexterm>
20648 <function>array_agg</function> ( <type>anynonarray</type> )
20649 <returnvalue>anyarray</returnvalue>
20650 </para>
20651 <para>
20652 Collects all the input values, including nulls, into an array.
20653 </para></entry>
20654 <entry>No</entry>
20655 </row>
20657 <row>
20658 <entry role="func_table_entry"><para role="func_signature">
20659 <function>array_agg</function> ( <type>anyarray</type> )
20660 <returnvalue>anyarray</returnvalue>
20661 </para>
20662 <para>
20663 Concatenates all the input arrays into an array of one higher
20664 dimension. (The inputs must all have the same dimensionality, and
20665 cannot be empty or null.)
20666 </para></entry>
20667 <entry>No</entry>
20668 </row>
20670 <row>
20671 <entry role="func_table_entry"><para role="func_signature">
20672 <indexterm>
20673 <primary>average</primary>
20674 </indexterm>
20675 <indexterm>
20676 <primary>avg</primary>
20677 </indexterm>
20678 <function>avg</function> ( <type>smallint</type> )
20679 <returnvalue>numeric</returnvalue>
20680 </para>
20681 <para role="func_signature">
20682 <function>avg</function> ( <type>integer</type> )
20683 <returnvalue>numeric</returnvalue>
20684 </para>
20685 <para role="func_signature">
20686 <function>avg</function> ( <type>bigint</type> )
20687 <returnvalue>numeric</returnvalue>
20688 </para>
20689 <para role="func_signature">
20690 <function>avg</function> ( <type>numeric</type> )
20691 <returnvalue>numeric</returnvalue>
20692 </para>
20693 <para role="func_signature">
20694 <function>avg</function> ( <type>real</type> )
20695 <returnvalue>double precision</returnvalue>
20696 </para>
20697 <para role="func_signature">
20698 <function>avg</function> ( <type>double precision</type> )
20699 <returnvalue>double precision</returnvalue>
20700 </para>
20701 <para role="func_signature">
20702 <function>avg</function> ( <type>interval</type> )
20703 <returnvalue>interval</returnvalue>
20704 </para>
20705 <para>
20706 Computes the average (arithmetic mean) of all the non-null input
20707 values.
20708 </para></entry>
20709 <entry>Yes</entry>
20710 </row>
20712 <row>
20713 <entry role="func_table_entry"><para role="func_signature">
20714 <indexterm>
20715 <primary>bit_and</primary>
20716 </indexterm>
20717 <function>bit_and</function> ( <type>smallint</type> )
20718 <returnvalue>smallint</returnvalue>
20719 </para>
20720 <para role="func_signature">
20721 <function>bit_and</function> ( <type>integer</type> )
20722 <returnvalue>integer</returnvalue>
20723 </para>
20724 <para role="func_signature">
20725 <function>bit_and</function> ( <type>bigint</type> )
20726 <returnvalue>bigint</returnvalue>
20727 </para>
20728 <para role="func_signature">
20729 <function>bit_and</function> ( <type>bit</type> )
20730 <returnvalue>bit</returnvalue>
20731 </para>
20732 <para>
20733 Computes the bitwise AND of all non-null input values.
20734 </para></entry>
20735 <entry>Yes</entry>
20736 </row>
20738 <row>
20739 <entry role="func_table_entry"><para role="func_signature">
20740 <indexterm>
20741 <primary>bit_or</primary>
20742 </indexterm>
20743 <function>bit_or</function> ( <type>smallint</type> )
20744 <returnvalue>smallint</returnvalue>
20745 </para>
20746 <para role="func_signature">
20747 <function>bit_or</function> ( <type>integer</type> )
20748 <returnvalue>integer</returnvalue>
20749 </para>
20750 <para role="func_signature">
20751 <function>bit_or</function> ( <type>bigint</type> )
20752 <returnvalue>bigint</returnvalue>
20753 </para>
20754 <para role="func_signature">
20755 <function>bit_or</function> ( <type>bit</type> )
20756 <returnvalue>bit</returnvalue>
20757 </para>
20758 <para>
20759 Computes the bitwise OR of all non-null input values.
20760 </para></entry>
20761 <entry>Yes</entry>
20762 </row>
20764 <row>
20765 <entry role="func_table_entry"><para role="func_signature">
20766 <indexterm>
20767 <primary>bit_xor</primary>
20768 </indexterm>
20769 <function>bit_xor</function> ( <type>smallint</type> )
20770 <returnvalue>smallint</returnvalue>
20771 </para>
20772 <para role="func_signature">
20773 <function>bit_xor</function> ( <type>integer</type> )
20774 <returnvalue>integer</returnvalue>
20775 </para>
20776 <para role="func_signature">
20777 <function>bit_xor</function> ( <type>bigint</type> )
20778 <returnvalue>bigint</returnvalue>
20779 </para>
20780 <para role="func_signature">
20781 <function>bit_xor</function> ( <type>bit</type> )
20782 <returnvalue>bit</returnvalue>
20783 </para>
20784 <para>
20785 Computes the bitwise exclusive OR of all non-null input values.
20786 Can be useful as a checksum for an unordered set of values.
20787 </para></entry>
20788 <entry>Yes</entry>
20789 </row>
20791 <row>
20792 <entry role="func_table_entry"><para role="func_signature">
20793 <indexterm>
20794 <primary>bool_and</primary>
20795 </indexterm>
20796 <function>bool_and</function> ( <type>boolean</type> )
20797 <returnvalue>boolean</returnvalue>
20798 </para>
20799 <para>
20800 Returns true if all non-null input values are true, otherwise false.
20801 </para></entry>
20802 <entry>Yes</entry>
20803 </row>
20805 <row>
20806 <entry role="func_table_entry"><para role="func_signature">
20807 <indexterm>
20808 <primary>bool_or</primary>
20809 </indexterm>
20810 <function>bool_or</function> ( <type>boolean</type> )
20811 <returnvalue>boolean</returnvalue>
20812 </para>
20813 <para>
20814 Returns true if any non-null input value is true, otherwise false.
20815 </para></entry>
20816 <entry>Yes</entry>
20817 </row>
20819 <row>
20820 <entry role="func_table_entry"><para role="func_signature">
20821 <indexterm>
20822 <primary>count</primary>
20823 </indexterm>
20824 <function>count</function> ( <literal>*</literal> )
20825 <returnvalue>bigint</returnvalue>
20826 </para>
20827 <para>
20828 Computes the number of input rows.
20829 </para></entry>
20830 <entry>Yes</entry>
20831 </row>
20833 <row>
20834 <entry role="func_table_entry"><para role="func_signature">
20835 <function>count</function> ( <type>"any"</type> )
20836 <returnvalue>bigint</returnvalue>
20837 </para>
20838 <para>
20839 Computes the number of input rows in which the input value is not
20840 null.
20841 </para></entry>
20842 <entry>Yes</entry>
20843 </row>
20845 <row>
20846 <entry role="func_table_entry"><para role="func_signature">
20847 <indexterm>
20848 <primary>every</primary>
20849 </indexterm>
20850 <function>every</function> ( <type>boolean</type> )
20851 <returnvalue>boolean</returnvalue>
20852 </para>
20853 <para>
20854 This is the SQL standard's equivalent to <function>bool_and</function>.
20855 </para></entry>
20856 <entry>Yes</entry>
20857 </row>
20859 <row>
20860 <entry role="func_table_entry"><para role="func_signature">
20861 <indexterm>
20862 <primary>json_agg</primary>
20863 </indexterm>
20864 <function>json_agg</function> ( <type>anyelement</type> )
20865 <returnvalue>json</returnvalue>
20866 </para>
20867 <para role="func_signature">
20868 <indexterm>
20869 <primary>jsonb_agg</primary>
20870 </indexterm>
20871 <function>jsonb_agg</function> ( <type>anyelement</type> )
20872 <returnvalue>jsonb</returnvalue>
20873 </para>
20874 <para>
20875 Collects all the input values, including nulls, into a JSON array.
20876 Values are converted to JSON as per <function>to_json</function>
20877 or <function>to_jsonb</function>.
20878 </para></entry>
20879 <entry>No</entry>
20880 </row>
20882 <row>
20883 <entry role="func_table_entry"><para role="func_signature">
20884 <indexterm>
20885 <primary>json_agg_strict</primary>
20886 </indexterm>
20887 <function>json_agg_strict</function> ( <type>anyelement</type> )
20888 <returnvalue>json</returnvalue>
20889 </para>
20890 <para role="func_signature">
20891 <indexterm>
20892 <primary>jsonb_agg_strict</primary>
20893 </indexterm>
20894 <function>jsonb_agg_strict</function> ( <type>anyelement</type> )
20895 <returnvalue>jsonb</returnvalue>
20896 </para>
20897 <para>
20898 Collects all the input values, skipping nulls, into a JSON array.
20899 Values are converted to JSON as per <function>to_json</function>
20900 or <function>to_jsonb</function>.
20901 </para></entry>
20902 <entry>No</entry>
20903 </row>
20905 <row>
20906 <entry role="func_table_entry"><para role="func_signature">
20907 <indexterm>
20908 <primary>json_object_agg</primary>
20909 </indexterm>
20910 <function>json_object_agg</function> ( <parameter>key</parameter>
20911 <type>"any"</type>, <parameter>value</parameter>
20912 <type>"any"</type> )
20913 <returnvalue>json</returnvalue>
20914 </para>
20915 <para role="func_signature">
20916 <indexterm>
20917 <primary>jsonb_object_agg</primary>
20918 </indexterm>
20919 <function>jsonb_object_agg</function> ( <parameter>key</parameter>
20920 <type>"any"</type>, <parameter>value</parameter>
20921 <type>"any"</type> )
20922 <returnvalue>jsonb</returnvalue>
20923 </para>
20924 <para>
20925 Collects all the key/value pairs into a JSON object. Key arguments
20926 are coerced to text; value arguments are converted as per
20927 <function>to_json</function> or <function>to_jsonb</function>
20928 Values can be null, but keys cannot.
20929 </para></entry>
20930 <entry>No</entry>
20931 </row>
20933 <row>
20934 <entry role="func_table_entry"><para role="func_signature">
20935 <indexterm>
20936 <primary>json_object_agg_strict</primary>
20937 </indexterm>
20938 <function>json_object_agg_strict</function> (
20939 <parameter>key</parameter> <type>"any"</type>,
20940 <parameter>value</parameter> <type>"any"</type> )
20941 <returnvalue>json</returnvalue>
20942 </para>
20943 <para role="func_signature">
20944 <indexterm>
20945 <primary>jsonb_object_agg_strict</primary>
20946 </indexterm>
20947 <function>jsonb_object_agg_strict</function> (
20948 <parameter>key</parameter> <type>"any"</type>,
20949 <parameter>value</parameter> <type>"any"</type> )
20950 <returnvalue>jsonb</returnvalue>
20951 </para>
20952 <para>
20953 Collects all the key/value pairs into a JSON object. Key arguments
20954 are coerced to text; value arguments are converted as per
20955 <function>to_json</function> or <function>to_jsonb</function>.
20956 The <parameter>key</parameter> can not be null. If the
20957 <parameter>value</parameter> is null then the entry is skipped,
20958 </para></entry>
20959 <entry>No</entry>
20960 </row>
20962 <row>
20963 <entry role="func_table_entry"><para role="func_signature">
20964 <indexterm>
20965 <primary>json_object_agg_unique</primary>
20966 </indexterm>
20967 <function>json_object_agg_unique</function> (
20968 <parameter>key</parameter> <type>"any"</type>,
20969 <parameter>value</parameter> <type>"any"</type> )
20970 <returnvalue>json</returnvalue>
20971 </para>
20972 <para role="func_signature">
20973 <indexterm>
20974 <primary>jsonb_object_agg_unique</primary>
20975 </indexterm>
20976 <function>jsonb_object_agg_unique</function> (
20977 <parameter>key</parameter> <type>"any"</type>,
20978 <parameter>value</parameter> <type>"any"</type> )
20979 <returnvalue>jsonb</returnvalue>
20980 </para>
20981 <para>
20982 Collects all the key/value pairs into a JSON object. Key arguments
20983 are coerced to text; value arguments are converted as per
20984 <function>to_json</function> or <function>to_jsonb</function>.
20985 Values can be null, but keys cannot.
20986 If there is a duplicate key an error is thrown.
20987 </para></entry>
20988 <entry>No</entry>
20989 </row>
20991 <row>
20992 <entry role="func_table_entry"><para role="func_signature">
20993 <indexterm>
20994 <primary>json_object_agg_unique_strict</primary>
20995 </indexterm>
20996 <function>json_object_agg_unique_strict</function> (
20997 <parameter>key</parameter> <type>"any"</type>,
20998 <parameter>value</parameter> <type>"any"</type> )
20999 <returnvalue>json</returnvalue>
21000 </para>
21001 <para role="func_signature">
21002 <indexterm>
21003 <primary>jsonb_object_agg_unique_strict</primary>
21004 </indexterm>
21005 <function>jsonb_object_agg_unique_strict</function> (
21006 <parameter>key</parameter> <type>"any"</type>,
21007 <parameter>value</parameter> <type>"any"</type> )
21008 <returnvalue>jsonb</returnvalue>
21009 </para>
21010 <para>
21011 Collects all the key/value pairs into a JSON object. Key arguments
21012 are coerced to text; value arguments are converted as per
21013 <function>to_json</function> or <function>to_jsonb</function>.
21014 The <parameter>key</parameter> can not be null. If the
21015 <parameter>value</parameter> is null then the entry is skipped,
21016 If there is a duplicate key an error is thrown.
21017 </para></entry>
21018 <entry>No</entry>
21019 </row>
21021 <row>
21022 <entry role="func_table_entry"><para role="func_signature">
21023 <indexterm>
21024 <primary>max</primary>
21025 </indexterm>
21026 <function>max</function> ( <replaceable>see text</replaceable> )
21027 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
21028 </para>
21029 <para>
21030 Computes the maximum of the non-null input
21031 values. Available for any numeric, string, date/time, or enum type,
21032 as well as <type>inet</type>, <type>interval</type>,
21033 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
21034 <type>tid</type>, <type>xid8</type>,
21035 and arrays of any of these types.
21036 </para></entry>
21037 <entry>Yes</entry>
21038 </row>
21040 <row>
21041 <entry role="func_table_entry"><para role="func_signature">
21042 <indexterm>
21043 <primary>min</primary>
21044 </indexterm>
21045 <function>min</function> ( <replaceable>see text</replaceable> )
21046 <returnvalue><replaceable>same as input type</replaceable></returnvalue>
21047 </para>
21048 <para>
21049 Computes the minimum of the non-null input
21050 values. Available for any numeric, string, date/time, or enum type,
21051 as well as <type>inet</type>, <type>interval</type>,
21052 <type>money</type>, <type>oid</type>, <type>pg_lsn</type>,
21053 <type>tid</type>, <type>xid8</type>,
21054 and arrays of any of these types.
21055 </para></entry>
21056 <entry>Yes</entry>
21057 </row>
21059 <row>
21060 <entry role="func_table_entry"><para role="func_signature">
21061 <indexterm>
21062 <primary>range_agg</primary>
21063 </indexterm>
21064 <function>range_agg</function> ( <parameter>value</parameter>
21065 <type>anyrange</type> )
21066 <returnvalue>anymultirange</returnvalue>
21067 </para>
21068 <para role="func_signature">
21069 <function>range_agg</function> ( <parameter>value</parameter>
21070 <type>anymultirange</type> )
21071 <returnvalue>anymultirange</returnvalue>
21072 </para>
21073 <para>
21074 Computes the union of the non-null input values.
21075 </para></entry>
21076 <entry>No</entry>
21077 </row>
21079 <row>
21080 <entry role="func_table_entry"><para role="func_signature">
21081 <indexterm>
21082 <primary>range_intersect_agg</primary>
21083 </indexterm>
21084 <function>range_intersect_agg</function> ( <parameter>value</parameter>
21085 <type>anyrange</type> )
21086 <returnvalue>anyrange</returnvalue>
21087 </para>
21088 <para role="func_signature">
21089 <function>range_intersect_agg</function> ( <parameter>value</parameter>
21090 <type>anymultirange</type> )
21091 <returnvalue>anymultirange</returnvalue>
21092 </para>
21093 <para>
21094 Computes the intersection of the non-null input values.
21095 </para></entry>
21096 <entry>No</entry>
21097 </row>
21099 <row>
21100 <entry role="func_table_entry"><para role="func_signature">
21101 <indexterm>
21102 <primary>string_agg</primary>
21103 </indexterm>
21104 <function>string_agg</function> ( <parameter>value</parameter>
21105 <type>text</type>, <parameter>delimiter</parameter> <type>text</type> )
21106 <returnvalue>text</returnvalue>
21107 </para>
21108 <para role="func_signature">
21109 <function>string_agg</function> ( <parameter>value</parameter>
21110 <type>bytea</type>, <parameter>delimiter</parameter> <type>bytea</type> )
21111 <returnvalue>bytea</returnvalue>
21112 </para>
21113 <para>
21114 Concatenates the non-null input values into a string. Each value
21115 after the first is preceded by the
21116 corresponding <parameter>delimiter</parameter> (if it's not null).
21117 </para></entry>
21118 <entry>No</entry>
21119 </row>
21121 <row>
21122 <entry role="func_table_entry"><para role="func_signature">
21123 <indexterm>
21124 <primary>sum</primary>
21125 </indexterm>
21126 <function>sum</function> ( <type>smallint</type> )
21127 <returnvalue>bigint</returnvalue>
21128 </para>
21129 <para role="func_signature">
21130 <function>sum</function> ( <type>integer</type> )
21131 <returnvalue>bigint</returnvalue>
21132 </para>
21133 <para role="func_signature">
21134 <function>sum</function> ( <type>bigint</type> )
21135 <returnvalue>numeric</returnvalue>
21136 </para>
21137 <para role="func_signature">
21138 <function>sum</function> ( <type>numeric</type> )
21139 <returnvalue>numeric</returnvalue>
21140 </para>
21141 <para role="func_signature">
21142 <function>sum</function> ( <type>real</type> )
21143 <returnvalue>real</returnvalue>
21144 </para>
21145 <para role="func_signature">
21146 <function>sum</function> ( <type>double precision</type> )
21147 <returnvalue>double precision</returnvalue>
21148 </para>
21149 <para role="func_signature">
21150 <function>sum</function> ( <type>interval</type> )
21151 <returnvalue>interval</returnvalue>
21152 </para>
21153 <para role="func_signature">
21154 <function>sum</function> ( <type>money</type> )
21155 <returnvalue>money</returnvalue>
21156 </para>
21157 <para>
21158 Computes the sum of the non-null input values.
21159 </para></entry>
21160 <entry>Yes</entry>
21161 </row>
21163 <row>
21164 <entry role="func_table_entry"><para role="func_signature">
21165 <indexterm>
21166 <primary>xmlagg</primary>
21167 </indexterm>
21168 <function>xmlagg</function> ( <type>xml</type> )
21169 <returnvalue>xml</returnvalue>
21170 </para>
21171 <para>
21172 Concatenates the non-null XML input values (see
21173 <xref linkend="functions-xml-xmlagg"/>).
21174 </para></entry>
21175 <entry>No</entry>
21176 </row>
21177 </tbody>
21178 </tgroup>
21179 </table>
21181 <para>
21182 It should be noted that except for <function>count</function>,
21183 these functions return a null value when no rows are selected. In
21184 particular, <function>sum</function> of no rows returns null, not
21185 zero as one might expect, and <function>array_agg</function>
21186 returns null rather than an empty array when there are no input
21187 rows. The <function>coalesce</function> function can be used to
21188 substitute zero or an empty array for null when necessary.
21189 </para>
21191 <para>
21192 The aggregate functions <function>array_agg</function>,
21193 <function>json_agg</function>, <function>jsonb_agg</function>,
21194 <function>json_agg_strict</function>, <function>jsonb_agg_strict</function>,
21195 <function>json_object_agg</function>, <function>jsonb_object_agg</function>,
21196 <function>json_object_agg_strict</function>, <function>jsonb_object_agg_strict</function>,
21197 <function>json_object_agg_unique</function>, <function>jsonb_object_agg_unique</function>,
21198 <function>json_object_agg_unique_strict</function>,
21199 <function>jsonb_object_agg_unique_strict</function>,
21200 <function>string_agg</function>,
21201 and <function>xmlagg</function>, as well as similar user-defined
21202 aggregate functions, produce meaningfully different result values
21203 depending on the order of the input values. This ordering is
21204 unspecified by default, but can be controlled by writing an
21205 <literal>ORDER BY</literal> clause within the aggregate call, as shown in
21206 <xref linkend="syntax-aggregates"/>.
21207 Alternatively, supplying the input values from a sorted subquery
21208 will usually work. For example:
21210 <screen><![CDATA[
21211 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
21212 ]]></screen>
21214 Beware that this approach can fail if the outer query level contains
21215 additional processing, such as a join, because that might cause the
21216 subquery's output to be reordered before the aggregate is computed.
21217 </para>
21219 <note>
21220 <para>
21221 In addition to the JSON aggregates shown here, see the <function>json_objectagg</function>
21222 and <function>json_arrayagg</function> constructors in <xref linkend="functions-sqljson"/>.
21223 </para>
21224 </note>
21226 <note>
21227 <indexterm>
21228 <primary>ANY</primary>
21229 </indexterm>
21230 <indexterm>
21231 <primary>SOME</primary>
21232 </indexterm>
21233 <para>
21234 The boolean aggregates <function>bool_and</function> and
21235 <function>bool_or</function> correspond to the standard SQL aggregates
21236 <function>every</function> and <function>any</function> or
21237 <function>some</function>.
21238 <productname>PostgreSQL</productname>
21239 supports <function>every</function>, but not <function>any</function>
21240 or <function>some</function>, because there is an ambiguity built into
21241 the standard syntax:
21242 <programlisting>
21243 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
21244 </programlisting>
21245 Here <function>ANY</function> can be considered either as introducing
21246 a subquery, or as being an aggregate function, if the subquery
21247 returns one row with a Boolean value.
21248 Thus the standard name cannot be given to these aggregates.
21249 </para>
21250 </note>
21252 <note>
21253 <para>
21254 Users accustomed to working with other SQL database management
21255 systems might be disappointed by the performance of the
21256 <function>count</function> aggregate when it is applied to the
21257 entire table. A query like:
21258 <programlisting>
21259 SELECT count(*) FROM sometable;
21260 </programlisting>
21261 will require effort proportional to the size of the table:
21262 <productname>PostgreSQL</productname> will need to scan either the
21263 entire table or the entirety of an index that includes all rows in
21264 the table.
21265 </para>
21266 </note>
21268 <para>
21269 <xref linkend="functions-aggregate-statistics-table"/> shows
21270 aggregate functions typically used in statistical analysis.
21271 (These are separated out merely to avoid cluttering the listing
21272 of more-commonly-used aggregates.) Functions shown as
21273 accepting <replaceable>numeric_type</replaceable> are available for all
21274 the types <type>smallint</type>, <type>integer</type>,
21275 <type>bigint</type>, <type>numeric</type>, <type>real</type>,
21276 and <type>double precision</type>.
21277 Where the description mentions
21278 <parameter>N</parameter>, it means the
21279 number of input rows for which all the input expressions are non-null.
21280 In all cases, null is returned if the computation is meaningless,
21281 for example when <parameter>N</parameter> is zero.
21282 </para>
21284 <indexterm>
21285 <primary>statistics</primary>
21286 </indexterm>
21287 <indexterm>
21288 <primary>linear regression</primary>
21289 </indexterm>
21291 <table id="functions-aggregate-statistics-table">
21292 <title>Aggregate Functions for Statistics</title>
21293 <tgroup cols="2">
21294 <colspec colname="col1" colwidth="10*"/>
21295 <colspec colname="col2" colwidth="1*"/>
21296 <thead>
21297 <row>
21298 <entry role="func_table_entry"><para role="func_signature">
21299 Function
21300 </para>
21301 <para>
21302 Description
21303 </para></entry>
21304 <entry>Partial Mode</entry>
21305 </row>
21306 </thead>
21308 <tbody>
21309 <row>
21310 <entry role="func_table_entry"><para role="func_signature">
21311 <indexterm>
21312 <primary>correlation</primary>
21313 </indexterm>
21314 <indexterm>
21315 <primary>corr</primary>
21316 </indexterm>
21317 <function>corr</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21318 <returnvalue>double precision</returnvalue>
21319 </para>
21320 <para>
21321 Computes the correlation coefficient.
21322 </para></entry>
21323 <entry>Yes</entry>
21324 </row>
21326 <row>
21327 <entry role="func_table_entry"><para role="func_signature">
21328 <indexterm>
21329 <primary>covariance</primary>
21330 <secondary>population</secondary>
21331 </indexterm>
21332 <indexterm>
21333 <primary>covar_pop</primary>
21334 </indexterm>
21335 <function>covar_pop</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21336 <returnvalue>double precision</returnvalue>
21337 </para>
21338 <para>
21339 Computes the population covariance.
21340 </para></entry>
21341 <entry>Yes</entry>
21342 </row>
21344 <row>
21345 <entry role="func_table_entry"><para role="func_signature">
21346 <indexterm>
21347 <primary>covariance</primary>
21348 <secondary>sample</secondary>
21349 </indexterm>
21350 <indexterm>
21351 <primary>covar_samp</primary>
21352 </indexterm>
21353 <function>covar_samp</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21354 <returnvalue>double precision</returnvalue>
21355 </para>
21356 <para>
21357 Computes the sample covariance.
21358 </para></entry>
21359 <entry>Yes</entry>
21360 </row>
21362 <row>
21363 <entry role="func_table_entry"><para role="func_signature">
21364 <indexterm>
21365 <primary>regr_avgx</primary>
21366 </indexterm>
21367 <function>regr_avgx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21368 <returnvalue>double precision</returnvalue>
21369 </para>
21370 <para>
21371 Computes the average of the independent variable,
21372 <literal>sum(<parameter>X</parameter>)/<parameter>N</parameter></literal>.
21373 </para></entry>
21374 <entry>Yes</entry>
21375 </row>
21377 <row>
21378 <entry role="func_table_entry"><para role="func_signature">
21379 <indexterm>
21380 <primary>regr_avgy</primary>
21381 </indexterm>
21382 <function>regr_avgy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21383 <returnvalue>double precision</returnvalue>
21384 </para>
21385 <para>
21386 Computes the average of the dependent variable,
21387 <literal>sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
21388 </para></entry>
21389 <entry>Yes</entry>
21390 </row>
21392 <row>
21393 <entry role="func_table_entry"><para role="func_signature">
21394 <indexterm>
21395 <primary>regr_count</primary>
21396 </indexterm>
21397 <function>regr_count</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21398 <returnvalue>bigint</returnvalue>
21399 </para>
21400 <para>
21401 Computes the number of rows in which both inputs are non-null.
21402 </para></entry>
21403 <entry>Yes</entry>
21404 </row>
21406 <row>
21407 <entry role="func_table_entry"><para role="func_signature">
21408 <indexterm>
21409 <primary>regression intercept</primary>
21410 </indexterm>
21411 <indexterm>
21412 <primary>regr_intercept</primary>
21413 </indexterm>
21414 <function>regr_intercept</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21415 <returnvalue>double precision</returnvalue>
21416 </para>
21417 <para>
21418 Computes the y-intercept of the least-squares-fit linear equation
21419 determined by the
21420 (<parameter>X</parameter>, <parameter>Y</parameter>) pairs.
21421 </para></entry>
21422 <entry>Yes</entry>
21423 </row>
21425 <row>
21426 <entry role="func_table_entry"><para role="func_signature">
21427 <indexterm>
21428 <primary>regr_r2</primary>
21429 </indexterm>
21430 <function>regr_r2</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21431 <returnvalue>double precision</returnvalue>
21432 </para>
21433 <para>
21434 Computes the square of the correlation coefficient.
21435 </para></entry>
21436 <entry>Yes</entry>
21437 </row>
21439 <row>
21440 <entry role="func_table_entry"><para role="func_signature">
21441 <indexterm>
21442 <primary>regression slope</primary>
21443 </indexterm>
21444 <indexterm>
21445 <primary>regr_slope</primary>
21446 </indexterm>
21447 <function>regr_slope</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21448 <returnvalue>double precision</returnvalue>
21449 </para>
21450 <para>
21451 Computes the slope of the least-squares-fit linear equation determined
21452 by the (<parameter>X</parameter>, <parameter>Y</parameter>)
21453 pairs.
21454 </para></entry>
21455 <entry>Yes</entry>
21456 </row>
21458 <row>
21459 <entry role="func_table_entry"><para role="func_signature">
21460 <indexterm>
21461 <primary>regr_sxx</primary>
21462 </indexterm>
21463 <function>regr_sxx</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21464 <returnvalue>double precision</returnvalue>
21465 </para>
21466 <para>
21467 Computes the <quote>sum of squares</quote> of the independent
21468 variable,
21469 <literal>sum(<parameter>X</parameter>^2) - sum(<parameter>X</parameter>)^2/<parameter>N</parameter></literal>.
21470 </para></entry>
21471 <entry>Yes</entry>
21472 </row>
21474 <row>
21475 <entry role="func_table_entry"><para role="func_signature">
21476 <indexterm>
21477 <primary>regr_sxy</primary>
21478 </indexterm>
21479 <function>regr_sxy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21480 <returnvalue>double precision</returnvalue>
21481 </para>
21482 <para>
21483 Computes the <quote>sum of products</quote> of independent times
21484 dependent variables,
21485 <literal>sum(<parameter>X</parameter>*<parameter>Y</parameter>) - sum(<parameter>X</parameter>) * sum(<parameter>Y</parameter>)/<parameter>N</parameter></literal>.
21486 </para></entry>
21487 <entry>Yes</entry>
21488 </row>
21490 <row>
21491 <entry role="func_table_entry"><para role="func_signature">
21492 <indexterm>
21493 <primary>regr_syy</primary>
21494 </indexterm>
21495 <function>regr_syy</function> ( <parameter>Y</parameter> <type>double precision</type>, <parameter>X</parameter> <type>double precision</type> )
21496 <returnvalue>double precision</returnvalue>
21497 </para>
21498 <para>
21499 Computes the <quote>sum of squares</quote> of the dependent
21500 variable,
21501 <literal>sum(<parameter>Y</parameter>^2) - sum(<parameter>Y</parameter>)^2/<parameter>N</parameter></literal>.
21502 </para></entry>
21503 <entry>Yes</entry>
21504 </row>
21506 <row>
21507 <entry role="func_table_entry"><para role="func_signature">
21508 <indexterm>
21509 <primary>standard deviation</primary>
21510 </indexterm>
21511 <indexterm>
21512 <primary>stddev</primary>
21513 </indexterm>
21514 <function>stddev</function> ( <replaceable>numeric_type</replaceable> )
21515 <returnvalue></returnvalue> <type>double precision</type>
21516 for <type>real</type> or <type>double precision</type>,
21517 otherwise <type>numeric</type>
21518 </para>
21519 <para>
21520 This is a historical alias for <function>stddev_samp</function>.
21521 </para></entry>
21522 <entry>Yes</entry>
21523 </row>
21525 <row>
21526 <entry role="func_table_entry"><para role="func_signature">
21527 <indexterm>
21528 <primary>standard deviation</primary>
21529 <secondary>population</secondary>
21530 </indexterm>
21531 <indexterm>
21532 <primary>stddev_pop</primary>
21533 </indexterm>
21534 <function>stddev_pop</function> ( <replaceable>numeric_type</replaceable> )
21535 <returnvalue></returnvalue> <type>double precision</type>
21536 for <type>real</type> or <type>double precision</type>,
21537 otherwise <type>numeric</type>
21538 </para>
21539 <para>
21540 Computes the population standard deviation of the input values.
21541 </para></entry>
21542 <entry>Yes</entry>
21543 </row>
21545 <row>
21546 <entry role="func_table_entry"><para role="func_signature">
21547 <indexterm>
21548 <primary>standard deviation</primary>
21549 <secondary>sample</secondary>
21550 </indexterm>
21551 <indexterm>
21552 <primary>stddev_samp</primary>
21553 </indexterm>
21554 <function>stddev_samp</function> ( <replaceable>numeric_type</replaceable> )
21555 <returnvalue></returnvalue> <type>double precision</type>
21556 for <type>real</type> or <type>double precision</type>,
21557 otherwise <type>numeric</type>
21558 </para>
21559 <para>
21560 Computes the sample standard deviation of the input values.
21561 </para></entry>
21562 <entry>Yes</entry>
21563 </row>
21565 <row>
21566 <entry role="func_table_entry"><para role="func_signature">
21567 <indexterm>
21568 <primary>variance</primary>
21569 </indexterm>
21570 <function>variance</function> ( <replaceable>numeric_type</replaceable> )
21571 <returnvalue></returnvalue> <type>double precision</type>
21572 for <type>real</type> or <type>double precision</type>,
21573 otherwise <type>numeric</type>
21574 </para>
21575 <para>
21576 This is a historical alias for <function>var_samp</function>.
21577 </para></entry>
21578 <entry>Yes</entry>
21579 </row>
21581 <row>
21582 <entry role="func_table_entry"><para role="func_signature">
21583 <indexterm>
21584 <primary>variance</primary>
21585 <secondary>population</secondary>
21586 </indexterm>
21587 <indexterm>
21588 <primary>var_pop</primary>
21589 </indexterm>
21590 <function>var_pop</function> ( <replaceable>numeric_type</replaceable> )
21591 <returnvalue></returnvalue> <type>double precision</type>
21592 for <type>real</type> or <type>double precision</type>,
21593 otherwise <type>numeric</type>
21594 </para>
21595 <para>
21596 Computes the population variance of the input values (square of the
21597 population standard deviation).
21598 </para></entry>
21599 <entry>Yes</entry>
21600 </row>
21602 <row>
21603 <entry role="func_table_entry"><para role="func_signature">
21604 <indexterm>
21605 <primary>variance</primary>
21606 <secondary>sample</secondary>
21607 </indexterm>
21608 <indexterm>
21609 <primary>var_samp</primary>
21610 </indexterm>
21611 <function>var_samp</function> ( <replaceable>numeric_type</replaceable> )
21612 <returnvalue></returnvalue> <type>double precision</type>
21613 for <type>real</type> or <type>double precision</type>,
21614 otherwise <type>numeric</type>
21615 </para>
21616 <para>
21617 Computes the sample variance of the input values (square of the sample
21618 standard deviation).
21619 </para></entry>
21620 <entry>Yes</entry>
21621 </row>
21622 </tbody>
21623 </tgroup>
21624 </table>
21626 <para>
21627 <xref linkend="functions-orderedset-table"/> shows some
21628 aggregate functions that use the <firstterm>ordered-set aggregate</firstterm>
21629 syntax. These functions are sometimes referred to as <quote>inverse
21630 distribution</quote> functions. Their aggregated input is introduced by
21631 <literal>ORDER BY</literal>, and they may also take a <firstterm>direct
21632 argument</firstterm> that is not aggregated, but is computed only once.
21633 All these functions ignore null values in their aggregated input.
21634 For those that take a <parameter>fraction</parameter> parameter, the
21635 fraction value must be between 0 and 1; an error is thrown if not.
21636 However, a null <parameter>fraction</parameter> value simply produces a
21637 null result.
21638 </para>
21640 <indexterm>
21641 <primary>ordered-set aggregate</primary>
21642 <secondary>built-in</secondary>
21643 </indexterm>
21644 <indexterm>
21645 <primary>inverse distribution</primary>
21646 </indexterm>
21648 <table id="functions-orderedset-table">
21649 <title>Ordered-Set Aggregate Functions</title>
21650 <tgroup cols="2">
21651 <colspec colname="col1" colwidth="10*"/>
21652 <colspec colname="col2" colwidth="1*"/>
21653 <thead>
21654 <row>
21655 <entry role="func_table_entry"><para role="func_signature">
21656 Function
21657 </para>
21658 <para>
21659 Description
21660 </para></entry>
21661 <entry>Partial Mode</entry>
21662 </row>
21663 </thead>
21665 <tbody>
21666 <row>
21667 <entry role="func_table_entry"><para role="func_signature">
21668 <indexterm>
21669 <primary>mode</primary>
21670 <secondary>statistical</secondary>
21671 </indexterm>
21672 <function>mode</function> () <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21673 <returnvalue>anyelement</returnvalue>
21674 </para>
21675 <para>
21676 Computes the <firstterm>mode</firstterm>, the most frequent
21677 value of the aggregated argument (arbitrarily choosing the first one
21678 if there are multiple equally-frequent values). The aggregated
21679 argument must be of a sortable type.
21680 </para></entry>
21681 <entry>No</entry>
21682 </row>
21684 <row>
21685 <entry role="func_table_entry"><para role="func_signature">
21686 <indexterm>
21687 <primary>percentile</primary>
21688 <secondary>continuous</secondary>
21689 </indexterm>
21690 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
21691 <returnvalue>double precision</returnvalue>
21692 </para>
21693 <para role="func_signature">
21694 <function>percentile_cont</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
21695 <returnvalue>interval</returnvalue>
21696 </para>
21697 <para>
21698 Computes the <firstterm>continuous percentile</firstterm>, a value
21699 corresponding to the specified <parameter>fraction</parameter>
21700 within the ordered set of aggregated argument values. This will
21701 interpolate between adjacent input items if needed.
21702 </para></entry>
21703 <entry>No</entry>
21704 </row>
21706 <row>
21707 <entry role="func_table_entry"><para role="func_signature">
21708 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>double precision</type> )
21709 <returnvalue>double precision[]</returnvalue>
21710 </para>
21711 <para role="func_signature">
21712 <function>percentile_cont</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>interval</type> )
21713 <returnvalue>interval[]</returnvalue>
21714 </para>
21715 <para>
21716 Computes multiple continuous percentiles. The result is an array of
21717 the same dimensions as the <parameter>fractions</parameter>
21718 parameter, with each non-null element replaced by the (possibly
21719 interpolated) value corresponding to that percentile.
21720 </para></entry>
21721 <entry>No</entry>
21722 </row>
21724 <row>
21725 <entry role="func_table_entry"><para role="func_signature">
21726 <indexterm>
21727 <primary>percentile</primary>
21728 <secondary>discrete</secondary>
21729 </indexterm>
21730 <function>percentile_disc</function> ( <parameter>fraction</parameter> <type>double precision</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21731 <returnvalue>anyelement</returnvalue>
21732 </para>
21733 <para>
21734 Computes the <firstterm>discrete percentile</firstterm>, the first
21735 value within the ordered set of aggregated argument values whose
21736 position in the ordering equals or exceeds the
21737 specified <parameter>fraction</parameter>. The aggregated
21738 argument must be of a sortable type.
21739 </para></entry>
21740 <entry>No</entry>
21741 </row>
21743 <row>
21744 <entry role="func_table_entry"><para role="func_signature">
21745 <function>percentile_disc</function> ( <parameter>fractions</parameter> <type>double precision[]</type> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <type>anyelement</type> )
21746 <returnvalue>anyarray</returnvalue>
21747 </para>
21748 <para>
21749 Computes multiple discrete percentiles. The result is an array of the
21750 same dimensions as the <parameter>fractions</parameter> parameter,
21751 with each non-null element replaced by the input value corresponding
21752 to that percentile.
21753 The aggregated argument must be of a sortable type.
21754 </para></entry>
21755 <entry>No</entry>
21756 </row>
21757 </tbody>
21758 </tgroup>
21759 </table>
21761 <indexterm>
21762 <primary>hypothetical-set aggregate</primary>
21763 <secondary>built-in</secondary>
21764 </indexterm>
21766 <para>
21767 Each of the <quote>hypothetical-set</quote> aggregates listed in
21768 <xref linkend="functions-hypothetical-table"/> is associated with a
21769 window function of the same name defined in
21770 <xref linkend="functions-window"/>. In each case, the aggregate's result
21771 is the value that the associated window function would have
21772 returned for the <quote>hypothetical</quote> row constructed from
21773 <replaceable>args</replaceable>, if such a row had been added to the sorted
21774 group of rows represented by the <replaceable>sorted_args</replaceable>.
21775 For each of these functions, the list of direct arguments
21776 given in <replaceable>args</replaceable> must match the number and types of
21777 the aggregated arguments given in <replaceable>sorted_args</replaceable>.
21778 Unlike most built-in aggregates, these aggregates are not strict, that is
21779 they do not drop input rows containing nulls. Null values sort according
21780 to the rule specified in the <literal>ORDER BY</literal> clause.
21781 </para>
21783 <table id="functions-hypothetical-table">
21784 <title>Hypothetical-Set Aggregate Functions</title>
21785 <tgroup cols="2">
21786 <colspec colname="col1" colwidth="10*"/>
21787 <colspec colname="col2" colwidth="1*"/>
21788 <thead>
21789 <row>
21790 <entry role="func_table_entry"><para role="func_signature">
21791 Function
21792 </para>
21793 <para>
21794 Description
21795 </para></entry>
21796 <entry>Partial Mode</entry>
21797 </row>
21798 </thead>
21800 <tbody>
21801 <row>
21802 <entry role="func_table_entry"><para role="func_signature">
21803 <indexterm>
21804 <primary>rank</primary>
21805 <secondary>hypothetical</secondary>
21806 </indexterm>
21807 <function>rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21808 <returnvalue>bigint</returnvalue>
21809 </para>
21810 <para>
21811 Computes the rank of the hypothetical row, with gaps; that is, the row
21812 number of the first row in its peer group.
21813 </para></entry>
21814 <entry>No</entry>
21815 </row>
21817 <row>
21818 <entry role="func_table_entry"><para role="func_signature">
21819 <indexterm>
21820 <primary>dense_rank</primary>
21821 <secondary>hypothetical</secondary>
21822 </indexterm>
21823 <function>dense_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21824 <returnvalue>bigint</returnvalue>
21825 </para>
21826 <para>
21827 Computes the rank of the hypothetical row, without gaps; this function
21828 effectively counts peer groups.
21829 </para></entry>
21830 <entry>No</entry>
21831 </row>
21833 <row>
21834 <entry role="func_table_entry"><para role="func_signature">
21835 <indexterm>
21836 <primary>percent_rank</primary>
21837 <secondary>hypothetical</secondary>
21838 </indexterm>
21839 <function>percent_rank</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21840 <returnvalue>double precision</returnvalue>
21841 </para>
21842 <para>
21843 Computes the relative rank of the hypothetical row, that is
21844 (<function>rank</function> - 1) / (total rows - 1).
21845 The value thus ranges from 0 to 1 inclusive.
21846 </para></entry>
21847 <entry>No</entry>
21848 </row>
21850 <row>
21851 <entry role="func_table_entry"><para role="func_signature">
21852 <indexterm>
21853 <primary>cume_dist</primary>
21854 <secondary>hypothetical</secondary>
21855 </indexterm>
21856 <function>cume_dist</function> ( <replaceable>args</replaceable> ) <literal>WITHIN GROUP</literal> ( <literal>ORDER BY</literal> <replaceable>sorted_args</replaceable> )
21857 <returnvalue>double precision</returnvalue>
21858 </para>
21859 <para>
21860 Computes the cumulative distribution, that is (number of rows
21861 preceding or peers with hypothetical row) / (total rows). The value
21862 thus ranges from 1/<parameter>N</parameter> to 1.
21863 </para></entry>
21864 <entry>No</entry>
21865 </row>
21866 </tbody>
21867 </tgroup>
21868 </table>
21870 <table id="functions-grouping-table">
21871 <title>Grouping Operations</title>
21872 <tgroup cols="1">
21873 <thead>
21874 <row>
21875 <entry role="func_table_entry"><para role="func_signature">
21876 Function
21877 </para>
21878 <para>
21879 Description
21880 </para></entry>
21881 </row>
21882 </thead>
21884 <tbody>
21885 <row>
21886 <entry role="func_table_entry"><para role="func_signature">
21887 <indexterm>
21888 <primary>GROUPING</primary>
21889 </indexterm>
21890 <function>GROUPING</function> ( <replaceable>group_by_expression(s)</replaceable> )
21891 <returnvalue>integer</returnvalue>
21892 </para>
21893 <para>
21894 Returns a bit mask indicating which <literal>GROUP BY</literal>
21895 expressions are not included in the current grouping set.
21896 Bits are assigned with the rightmost argument corresponding to the
21897 least-significant bit; each bit is 0 if the corresponding expression
21898 is included in the grouping criteria of the grouping set generating
21899 the current result row, and 1 if it is not included.
21900 </para></entry>
21901 </row>
21902 </tbody>
21903 </tgroup>
21904 </table>
21906 <para>
21907 The grouping operations shown in
21908 <xref linkend="functions-grouping-table"/> are used in conjunction with
21909 grouping sets (see <xref linkend="queries-grouping-sets"/>) to distinguish
21910 result rows. The arguments to the <literal>GROUPING</literal> function
21911 are not actually evaluated, but they must exactly match expressions given
21912 in the <literal>GROUP BY</literal> clause of the associated query level.
21913 For example:
21914 <screen>
21915 <prompt>=&gt;</prompt> <userinput>SELECT * FROM items_sold;</userinput>
21916 make | model | sales
21917 -------+-------+-------
21918 Foo | GT | 10
21919 Foo | Tour | 20
21920 Bar | City | 15
21921 Bar | Sport | 5
21922 (4 rows)
21924 <prompt>=&gt;</prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);</userinput>
21925 make | model | grouping | sum
21926 -------+-------+----------+-----
21927 Foo | GT | 0 | 10
21928 Foo | Tour | 0 | 20
21929 Bar | City | 0 | 15
21930 Bar | Sport | 0 | 5
21931 Foo | | 1 | 30
21932 Bar | | 1 | 20
21933 | | 3 | 50
21934 (7 rows)
21935 </screen>
21936 Here, the <literal>grouping</literal> value <literal>0</literal> in the
21937 first four rows shows that those have been grouped normally, over both the
21938 grouping columns. The value <literal>1</literal> indicates
21939 that <literal>model</literal> was not grouped by in the next-to-last two
21940 rows, and the value <literal>3</literal> indicates that
21941 neither <literal>make</literal> nor <literal>model</literal> was grouped
21942 by in the last row (which therefore is an aggregate over all the input
21943 rows).
21944 </para>
21946 </sect1>
21948 <sect1 id="functions-window">
21949 <title>Window Functions</title>
21951 <indexterm zone="functions-window">
21952 <primary>window function</primary>
21953 <secondary>built-in</secondary>
21954 </indexterm>
21956 <para>
21957 <firstterm>Window functions</firstterm> provide the ability to perform
21958 calculations across sets of rows that are related to the current query
21959 row. See <xref linkend="tutorial-window"/> for an introduction to this
21960 feature, and <xref linkend="syntax-window-functions"/> for syntax
21961 details.
21962 </para>
21964 <para>
21965 The built-in window functions are listed in
21966 <xref linkend="functions-window-table"/>. Note that these functions
21967 <emphasis>must</emphasis> be invoked using window function syntax, i.e., an
21968 <literal>OVER</literal> clause is required.
21969 </para>
21971 <para>
21972 In addition to these functions, any built-in or user-defined
21973 ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates)
21974 can be used as a window function; see
21975 <xref linkend="functions-aggregate"/> for a list of the built-in aggregates.
21976 Aggregate functions act as window functions only when an <literal>OVER</literal>
21977 clause follows the call; otherwise they act as plain aggregates
21978 and return a single row for the entire set.
21979 </para>
21981 <table id="functions-window-table">
21982 <title>General-Purpose Window Functions</title>
21983 <tgroup cols="1">
21984 <thead>
21985 <row>
21986 <entry role="func_table_entry"><para role="func_signature">
21987 Function
21988 </para>
21989 <para>
21990 Description
21991 </para></entry>
21992 </row>
21993 </thead>
21995 <tbody>
21996 <row>
21997 <entry role="func_table_entry"><para role="func_signature">
21998 <indexterm>
21999 <primary>row_number</primary>
22000 </indexterm>
22001 <function>row_number</function> ()
22002 <returnvalue>bigint</returnvalue>
22003 </para>
22004 <para>
22005 Returns the number of the current row within its partition, counting
22006 from 1.
22007 </para></entry>
22008 </row>
22010 <row>
22011 <entry role="func_table_entry"><para role="func_signature">
22012 <indexterm>
22013 <primary>rank</primary>
22014 </indexterm>
22015 <function>rank</function> ()
22016 <returnvalue>bigint</returnvalue>
22017 </para>
22018 <para>
22019 Returns the rank of the current row, with gaps; that is,
22020 the <function>row_number</function> of the first row in its peer
22021 group.
22022 </para></entry>
22023 </row>
22025 <row>
22026 <entry role="func_table_entry"><para role="func_signature">
22027 <indexterm>
22028 <primary>dense_rank</primary>
22029 </indexterm>
22030 <function>dense_rank</function> ()
22031 <returnvalue>bigint</returnvalue>
22032 </para>
22033 <para>
22034 Returns the rank of the current row, without gaps; this function
22035 effectively counts peer groups.
22036 </para></entry>
22037 </row>
22039 <row>
22040 <entry role="func_table_entry"><para role="func_signature">
22041 <indexterm>
22042 <primary>percent_rank</primary>
22043 </indexterm>
22044 <function>percent_rank</function> ()
22045 <returnvalue>double precision</returnvalue>
22046 </para>
22047 <para>
22048 Returns the relative rank of the current row, that is
22049 (<function>rank</function> - 1) / (total partition rows - 1).
22050 The value thus ranges from 0 to 1 inclusive.
22051 </para></entry>
22052 </row>
22054 <row>
22055 <entry role="func_table_entry"><para role="func_signature">
22056 <indexterm>
22057 <primary>cume_dist</primary>
22058 </indexterm>
22059 <function>cume_dist</function> ()
22060 <returnvalue>double precision</returnvalue>
22061 </para>
22062 <para>
22063 Returns the cumulative distribution, that is (number of partition rows
22064 preceding or peers with current row) / (total partition rows).
22065 The value thus ranges from 1/<parameter>N</parameter> to 1.
22066 </para></entry>
22067 </row>
22069 <row>
22070 <entry role="func_table_entry"><para role="func_signature">
22071 <indexterm>
22072 <primary>ntile</primary>
22073 </indexterm>
22074 <function>ntile</function> ( <parameter>num_buckets</parameter> <type>integer</type> )
22075 <returnvalue>integer</returnvalue>
22076 </para>
22077 <para>
22078 Returns an integer ranging from 1 to the argument value, dividing the
22079 partition as equally as possible.
22080 </para></entry>
22081 </row>
22083 <row>
22084 <entry role="func_table_entry"><para role="func_signature">
22085 <indexterm>
22086 <primary>lag</primary>
22087 </indexterm>
22088 <function>lag</function> ( <parameter>value</parameter> <type>anycompatible</type>
22089 <optional>, <parameter>offset</parameter> <type>integer</type>
22090 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
22091 <returnvalue>anycompatible</returnvalue>
22092 </para>
22093 <para>
22094 Returns <parameter>value</parameter> evaluated at
22095 the row that is <parameter>offset</parameter>
22096 rows before the current row within the partition; if there is no such
22097 row, instead returns <parameter>default</parameter>
22098 (which must be of a type compatible with
22099 <parameter>value</parameter>).
22100 Both <parameter>offset</parameter> and
22101 <parameter>default</parameter> are evaluated
22102 with respect to the current row. If omitted,
22103 <parameter>offset</parameter> defaults to 1 and
22104 <parameter>default</parameter> to <literal>NULL</literal>.
22105 </para></entry>
22106 </row>
22108 <row>
22109 <entry role="func_table_entry"><para role="func_signature">
22110 <indexterm>
22111 <primary>lead</primary>
22112 </indexterm>
22113 <function>lead</function> ( <parameter>value</parameter> <type>anycompatible</type>
22114 <optional>, <parameter>offset</parameter> <type>integer</type>
22115 <optional>, <parameter>default</parameter> <type>anycompatible</type> </optional></optional> )
22116 <returnvalue>anycompatible</returnvalue>
22117 </para>
22118 <para>
22119 Returns <parameter>value</parameter> evaluated at
22120 the row that is <parameter>offset</parameter>
22121 rows after the current row within the partition; if there is no such
22122 row, instead returns <parameter>default</parameter>
22123 (which must be of a type compatible with
22124 <parameter>value</parameter>).
22125 Both <parameter>offset</parameter> and
22126 <parameter>default</parameter> are evaluated
22127 with respect to the current row. If omitted,
22128 <parameter>offset</parameter> defaults to 1 and
22129 <parameter>default</parameter> to <literal>NULL</literal>.
22130 </para></entry>
22131 </row>
22133 <row>
22134 <entry role="func_table_entry"><para role="func_signature">
22135 <indexterm>
22136 <primary>first_value</primary>
22137 </indexterm>
22138 <function>first_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
22139 <returnvalue>anyelement</returnvalue>
22140 </para>
22141 <para>
22142 Returns <parameter>value</parameter> evaluated
22143 at the row that is the first row of the window frame.
22144 </para></entry>
22145 </row>
22147 <row>
22148 <entry role="func_table_entry"><para role="func_signature">
22149 <indexterm>
22150 <primary>last_value</primary>
22151 </indexterm>
22152 <function>last_value</function> ( <parameter>value</parameter> <type>anyelement</type> )
22153 <returnvalue>anyelement</returnvalue>
22154 </para>
22155 <para>
22156 Returns <parameter>value</parameter> evaluated
22157 at the row that is the last row of the window frame.
22158 </para></entry>
22159 </row>
22161 <row>
22162 <entry role="func_table_entry"><para role="func_signature">
22163 <indexterm>
22164 <primary>nth_value</primary>
22165 </indexterm>
22166 <function>nth_value</function> ( <parameter>value</parameter> <type>anyelement</type>, <parameter>n</parameter> <type>integer</type> )
22167 <returnvalue>anyelement</returnvalue>
22168 </para>
22169 <para>
22170 Returns <parameter>value</parameter> evaluated
22171 at the row that is the <parameter>n</parameter>'th
22172 row of the window frame (counting from 1);
22173 returns <literal>NULL</literal> if there is no such row.
22174 </para></entry>
22175 </row>
22176 </tbody>
22177 </tgroup>
22178 </table>
22180 <para>
22181 All of the functions listed in
22182 <xref linkend="functions-window-table"/> depend on the sort ordering
22183 specified by the <literal>ORDER BY</literal> clause of the associated window
22184 definition. Rows that are not distinct when considering only the
22185 <literal>ORDER BY</literal> columns are said to be <firstterm>peers</firstterm>.
22186 The four ranking functions (including <function>cume_dist</function>) are
22187 defined so that they give the same answer for all rows of a peer group.
22188 </para>
22190 <para>
22191 Note that <function>first_value</function>, <function>last_value</function>, and
22192 <function>nth_value</function> consider only the rows within the <quote>window
22193 frame</quote>, which by default contains the rows from the start of the
22194 partition through the last peer of the current row. This is
22195 likely to give unhelpful results for <function>last_value</function> and
22196 sometimes also <function>nth_value</function>. You can redefine the frame by
22197 adding a suitable frame specification (<literal>RANGE</literal>,
22198 <literal>ROWS</literal> or <literal>GROUPS</literal>) to
22199 the <literal>OVER</literal> clause.
22200 See <xref linkend="syntax-window-functions"/> for more information
22201 about frame specifications.
22202 </para>
22204 <para>
22205 When an aggregate function is used as a window function, it aggregates
22206 over the rows within the current row's window frame.
22207 An aggregate used with <literal>ORDER BY</literal> and the default window frame
22208 definition produces a <quote>running sum</quote> type of behavior, which may or
22209 may not be what's wanted. To obtain
22210 aggregation over the whole partition, omit <literal>ORDER BY</literal> or use
22211 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</literal>.
22212 Other frame specifications can be used to obtain other effects.
22213 </para>
22215 <note>
22216 <para>
22217 The SQL standard defines a <literal>RESPECT NULLS</literal> or
22218 <literal>IGNORE NULLS</literal> option for <function>lead</function>, <function>lag</function>,
22219 <function>first_value</function>, <function>last_value</function>, and
22220 <function>nth_value</function>. This is not implemented in
22221 <productname>PostgreSQL</productname>: the behavior is always the
22222 same as the standard's default, namely <literal>RESPECT NULLS</literal>.
22223 Likewise, the standard's <literal>FROM FIRST</literal> or <literal>FROM LAST</literal>
22224 option for <function>nth_value</function> is not implemented: only the
22225 default <literal>FROM FIRST</literal> behavior is supported. (You can achieve
22226 the result of <literal>FROM LAST</literal> by reversing the <literal>ORDER BY</literal>
22227 ordering.)
22228 </para>
22229 </note>
22231 </sect1>
22233 <sect1 id="functions-subquery">
22234 <title>Subquery Expressions</title>
22236 <indexterm>
22237 <primary>EXISTS</primary>
22238 </indexterm>
22240 <indexterm>
22241 <primary>IN</primary>
22242 </indexterm>
22244 <indexterm>
22245 <primary>NOT IN</primary>
22246 </indexterm>
22248 <indexterm>
22249 <primary>ANY</primary>
22250 </indexterm>
22252 <indexterm>
22253 <primary>ALL</primary>
22254 </indexterm>
22256 <indexterm>
22257 <primary>SOME</primary>
22258 </indexterm>
22260 <indexterm>
22261 <primary>subquery</primary>
22262 </indexterm>
22264 <para>
22265 This section describes the <acronym>SQL</acronym>-compliant subquery
22266 expressions available in <productname>PostgreSQL</productname>.
22267 All of the expression forms documented in this section return
22268 Boolean (true/false) results.
22269 </para>
22271 <sect2 id="functions-subquery-exists">
22272 <title><literal>EXISTS</literal></title>
22274 <synopsis>
22275 EXISTS (<replaceable>subquery</replaceable>)
22276 </synopsis>
22278 <para>
22279 The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</command> statement,
22280 or <firstterm>subquery</firstterm>. The
22281 subquery is evaluated to determine whether it returns any rows.
22282 If it returns at least one row, the result of <token>EXISTS</token> is
22283 <quote>true</quote>; if the subquery returns no rows, the result of <token>EXISTS</token>
22284 is <quote>false</quote>.
22285 </para>
22287 <para>
22288 The subquery can refer to variables from the surrounding query,
22289 which will act as constants during any one evaluation of the subquery.
22290 </para>
22292 <para>
22293 The subquery will generally only be executed long enough to determine
22294 whether at least one row is returned, not all the way to completion.
22295 It is unwise to write a subquery that has side effects (such as
22296 calling sequence functions); whether the side effects occur
22297 might be unpredictable.
22298 </para>
22300 <para>
22301 Since the result depends only on whether any rows are returned,
22302 and not on the contents of those rows, the output list of the
22303 subquery is normally unimportant. A common coding convention is
22304 to write all <literal>EXISTS</literal> tests in the form
22305 <literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
22306 this rule however, such as subqueries that use <token>INTERSECT</token>.
22307 </para>
22309 <para>
22310 This simple example is like an inner join on <literal>col2</literal>, but
22311 it produces at most one output row for each <literal>tab1</literal> row,
22312 even if there are several matching <literal>tab2</literal> rows:
22313 <screen>
22314 SELECT col1
22315 FROM tab1
22316 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
22317 </screen>
22318 </para>
22319 </sect2>
22321 <sect2 id="functions-subquery-in">
22322 <title><literal>IN</literal></title>
22324 <synopsis>
22325 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
22326 </synopsis>
22328 <para>
22329 The right-hand side is a parenthesized
22330 subquery, which must return exactly one column. The left-hand expression
22331 is evaluated and compared to each row of the subquery result.
22332 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
22333 The result is <quote>false</quote> if no equal row is found (including the
22334 case where the subquery returns no rows).
22335 </para>
22337 <para>
22338 Note that if the left-hand expression yields null, or if there are
22339 no equal right-hand values and at least one right-hand row yields
22340 null, the result of the <token>IN</token> construct will be null, not false.
22341 This is in accordance with SQL's normal rules for Boolean combinations
22342 of null values.
22343 </para>
22345 <para>
22346 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22347 be evaluated completely.
22348 </para>
22350 <synopsis>
22351 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
22352 </synopsis>
22354 <para>
22355 The left-hand side of this form of <token>IN</token> is a row constructor,
22356 as described in <xref linkend="sql-syntax-row-constructors"/>.
22357 The right-hand side is a parenthesized
22358 subquery, which must return exactly as many columns as there are
22359 expressions in the left-hand row. The left-hand expressions are
22360 evaluated and compared row-wise to each row of the subquery result.
22361 The result of <token>IN</token> is <quote>true</quote> if any equal subquery row is found.
22362 The result is <quote>false</quote> if no equal row is found (including the
22363 case where the subquery returns no rows).
22364 </para>
22366 <para>
22367 As usual, null values in the rows are combined per
22368 the normal rules of SQL Boolean expressions. Two rows are considered
22369 equal if all their corresponding members are non-null and equal; the rows
22370 are unequal if any corresponding members are non-null and unequal;
22371 otherwise the result of that row comparison is unknown (null).
22372 If all the per-row results are either unequal or null, with at least one
22373 null, then the result of <token>IN</token> is null.
22374 </para>
22375 </sect2>
22377 <sect2 id="functions-subquery-notin">
22378 <title><literal>NOT IN</literal></title>
22380 <synopsis>
22381 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
22382 </synopsis>
22384 <para>
22385 The right-hand side is a parenthesized
22386 subquery, which must return exactly one column. The left-hand expression
22387 is evaluated and compared to each row of the subquery result.
22388 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
22389 are found (including the case where the subquery returns no rows).
22390 The result is <quote>false</quote> if any equal row is found.
22391 </para>
22393 <para>
22394 Note that if the left-hand expression yields null, or if there are
22395 no equal right-hand values and at least one right-hand row yields
22396 null, the result of the <token>NOT IN</token> construct will be null, not true.
22397 This is in accordance with SQL's normal rules for Boolean combinations
22398 of null values.
22399 </para>
22401 <para>
22402 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22403 be evaluated completely.
22404 </para>
22406 <synopsis>
22407 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
22408 </synopsis>
22410 <para>
22411 The left-hand side of this form of <token>NOT IN</token> is a row constructor,
22412 as described in <xref linkend="sql-syntax-row-constructors"/>.
22413 The right-hand side is a parenthesized
22414 subquery, which must return exactly as many columns as there are
22415 expressions in the left-hand row. The left-hand expressions are
22416 evaluated and compared row-wise to each row of the subquery result.
22417 The result of <token>NOT IN</token> is <quote>true</quote> if only unequal subquery rows
22418 are found (including the case where the subquery returns no rows).
22419 The result is <quote>false</quote> if any equal row is found.
22420 </para>
22422 <para>
22423 As usual, null values in the rows are combined per
22424 the normal rules of SQL Boolean expressions. Two rows are considered
22425 equal if all their corresponding members are non-null and equal; the rows
22426 are unequal if any corresponding members are non-null and unequal;
22427 otherwise the result of that row comparison is unknown (null).
22428 If all the per-row results are either unequal or null, with at least one
22429 null, then the result of <token>NOT IN</token> is null.
22430 </para>
22431 </sect2>
22433 <sect2 id="functions-subquery-any-some">
22434 <title><literal>ANY</literal>/<literal>SOME</literal></title>
22436 <synopsis>
22437 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
22438 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
22439 </synopsis>
22441 <para>
22442 The right-hand side is a parenthesized
22443 subquery, which must return exactly one column. The left-hand expression
22444 is evaluated and compared to each row of the subquery result using the
22445 given <replaceable>operator</replaceable>, which must yield a Boolean
22446 result.
22447 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
22448 The result is <quote>false</quote> if no true result is found (including the
22449 case where the subquery returns no rows).
22450 </para>
22452 <para>
22453 <token>SOME</token> is a synonym for <token>ANY</token>.
22454 <token>IN</token> is equivalent to <literal>= ANY</literal>.
22455 </para>
22457 <para>
22458 Note that if there are no successes and at least one right-hand row yields
22459 null for the operator's result, the result of the <token>ANY</token> construct
22460 will be null, not false.
22461 This is in accordance with SQL's normal rules for Boolean combinations
22462 of null values.
22463 </para>
22465 <para>
22466 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22467 be evaluated completely.
22468 </para>
22470 <synopsis>
22471 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
22472 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
22473 </synopsis>
22475 <para>
22476 The left-hand side of this form of <token>ANY</token> is a row constructor,
22477 as described in <xref linkend="sql-syntax-row-constructors"/>.
22478 The right-hand side is a parenthesized
22479 subquery, which must return exactly as many columns as there are
22480 expressions in the left-hand row. The left-hand expressions are
22481 evaluated and compared row-wise to each row of the subquery result,
22482 using the given <replaceable>operator</replaceable>.
22483 The result of <token>ANY</token> is <quote>true</quote> if the comparison
22484 returns true for any subquery row.
22485 The result is <quote>false</quote> if the comparison returns false for every
22486 subquery row (including the case where the subquery returns no
22487 rows).
22488 The result is NULL if no comparison with a subquery row returns true,
22489 and at least one comparison returns NULL.
22490 </para>
22492 <para>
22493 See <xref linkend="row-wise-comparison"/> for details about the meaning
22494 of a row constructor comparison.
22495 </para>
22496 </sect2>
22498 <sect2 id="functions-subquery-all">
22499 <title><literal>ALL</literal></title>
22501 <synopsis>
22502 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
22503 </synopsis>
22505 <para>
22506 The right-hand side is a parenthesized
22507 subquery, which must return exactly one column. The left-hand expression
22508 is evaluated and compared to each row of the subquery result using the
22509 given <replaceable>operator</replaceable>, which must yield a Boolean
22510 result.
22511 The result of <token>ALL</token> is <quote>true</quote> if all rows yield true
22512 (including the case where the subquery returns no rows).
22513 The result is <quote>false</quote> if any false result is found.
22514 The result is NULL if no comparison with a subquery row returns false,
22515 and at least one comparison returns NULL.
22516 </para>
22518 <para>
22519 <token>NOT IN</token> is equivalent to <literal>&lt;&gt; ALL</literal>.
22520 </para>
22522 <para>
22523 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
22524 be evaluated completely.
22525 </para>
22527 <synopsis>
22528 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
22529 </synopsis>
22531 <para>
22532 The left-hand side of this form of <token>ALL</token> is a row constructor,
22533 as described in <xref linkend="sql-syntax-row-constructors"/>.
22534 The right-hand side is a parenthesized
22535 subquery, which must return exactly as many columns as there are
22536 expressions in the left-hand row. The left-hand expressions are
22537 evaluated and compared row-wise to each row of the subquery result,
22538 using the given <replaceable>operator</replaceable>.
22539 The result of <token>ALL</token> is <quote>true</quote> if the comparison
22540 returns true for all subquery rows (including the
22541 case where the subquery returns no rows).
22542 The result is <quote>false</quote> if the comparison returns false for any
22543 subquery row.
22544 The result is NULL if no comparison with a subquery row returns false,
22545 and at least one comparison returns NULL.
22546 </para>
22548 <para>
22549 See <xref linkend="row-wise-comparison"/> for details about the meaning
22550 of a row constructor comparison.
22551 </para>
22552 </sect2>
22554 <sect2>
22555 <title>Single-Row Comparison</title>
22557 <indexterm zone="functions-subquery">
22558 <primary>comparison</primary>
22559 <secondary>subquery result row</secondary>
22560 </indexterm>
22562 <synopsis>
22563 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
22564 </synopsis>
22566 <para>
22567 The left-hand side is a row constructor,
22568 as described in <xref linkend="sql-syntax-row-constructors"/>.
22569 The right-hand side is a parenthesized subquery, which must return exactly
22570 as many columns as there are expressions in the left-hand row. Furthermore,
22571 the subquery cannot return more than one row. (If it returns zero rows,
22572 the result is taken to be null.) The left-hand side is evaluated and
22573 compared row-wise to the single subquery result row.
22574 </para>
22576 <para>
22577 See <xref linkend="row-wise-comparison"/> for details about the meaning
22578 of a row constructor comparison.
22579 </para>
22580 </sect2>
22581 </sect1>
22584 <sect1 id="functions-comparisons">
22585 <title>Row and Array Comparisons</title>
22587 <indexterm>
22588 <primary>IN</primary>
22589 </indexterm>
22591 <indexterm>
22592 <primary>NOT IN</primary>
22593 </indexterm>
22595 <indexterm>
22596 <primary>ANY</primary>
22597 </indexterm>
22599 <indexterm>
22600 <primary>ALL</primary>
22601 </indexterm>
22603 <indexterm>
22604 <primary>SOME</primary>
22605 </indexterm>
22607 <indexterm>
22608 <primary>composite type</primary>
22609 <secondary>comparison</secondary>
22610 </indexterm>
22612 <indexterm>
22613 <primary>row-wise comparison</primary>
22614 </indexterm>
22616 <indexterm>
22617 <primary>comparison</primary>
22618 <secondary>composite type</secondary>
22619 </indexterm>
22621 <indexterm>
22622 <primary>comparison</primary>
22623 <secondary>row constructor</secondary>
22624 </indexterm>
22626 <indexterm>
22627 <primary>IS DISTINCT FROM</primary>
22628 </indexterm>
22630 <indexterm>
22631 <primary>IS NOT DISTINCT FROM</primary>
22632 </indexterm>
22634 <para>
22635 This section describes several specialized constructs for making
22636 multiple comparisons between groups of values. These forms are
22637 syntactically related to the subquery forms of the previous section,
22638 but do not involve subqueries.
22639 The forms involving array subexpressions are
22640 <productname>PostgreSQL</productname> extensions; the rest are
22641 <acronym>SQL</acronym>-compliant.
22642 All of the expression forms documented in this section return
22643 Boolean (true/false) results.
22644 </para>
22646 <sect2 id="functions-comparisons-in-scalar">
22647 <title><literal>IN</literal></title>
22649 <synopsis>
22650 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
22651 </synopsis>
22653 <para>
22654 The right-hand side is a parenthesized list
22655 of scalar expressions. The result is <quote>true</quote> if the left-hand expression's
22656 result is equal to any of the right-hand expressions. This is a shorthand
22657 notation for
22659 <synopsis>
22660 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
22662 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
22665 </synopsis>
22666 </para>
22668 <para>
22669 Note that if the left-hand expression yields null, or if there are
22670 no equal right-hand values and at least one right-hand expression yields
22671 null, the result of the <token>IN</token> construct will be null, not false.
22672 This is in accordance with SQL's normal rules for Boolean combinations
22673 of null values.
22674 </para>
22675 </sect2>
22677 <sect2>
22678 <title><literal>NOT IN</literal></title>
22680 <synopsis>
22681 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
22682 </synopsis>
22684 <para>
22685 The right-hand side is a parenthesized list
22686 of scalar expressions. The result is <quote>true</quote> if the left-hand expression's
22687 result is unequal to all of the right-hand expressions. This is a shorthand
22688 notation for
22690 <synopsis>
22691 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value1</replaceable>
22693 <replaceable>expression</replaceable> &lt;&gt; <replaceable>value2</replaceable>
22696 </synopsis>
22697 </para>
22699 <para>
22700 Note that if the left-hand expression yields null, or if there are
22701 no equal right-hand values and at least one right-hand expression yields
22702 null, the result of the <token>NOT IN</token> construct will be null, not true
22703 as one might naively expect.
22704 This is in accordance with SQL's normal rules for Boolean combinations
22705 of null values.
22706 </para>
22708 <tip>
22709 <para>
22710 <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
22711 cases. However, null values are much more likely to trip up the novice when
22712 working with <token>NOT IN</token> than when working with <token>IN</token>.
22713 It is best to express your condition positively if possible.
22714 </para>
22715 </tip>
22716 </sect2>
22718 <sect2>
22719 <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
22721 <synopsis>
22722 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
22723 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
22724 </synopsis>
22726 <para>
22727 The right-hand side is a parenthesized expression, which must yield an
22728 array value.
22729 The left-hand expression
22730 is evaluated and compared to each element of the array using the
22731 given <replaceable>operator</replaceable>, which must yield a Boolean
22732 result.
22733 The result of <token>ANY</token> is <quote>true</quote> if any true result is obtained.
22734 The result is <quote>false</quote> if no true result is found (including the
22735 case where the array has zero elements).
22736 </para>
22738 <para>
22739 If the array expression yields a null array, the result of
22740 <token>ANY</token> will be null. If the left-hand expression yields null,
22741 the result of <token>ANY</token> is ordinarily null (though a non-strict
22742 comparison operator could possibly yield a different result).
22743 Also, if the right-hand array contains any null elements and no true
22744 comparison result is obtained, the result of <token>ANY</token>
22745 will be null, not false (again, assuming a strict comparison operator).
22746 This is in accordance with SQL's normal rules for Boolean combinations
22747 of null values.
22748 </para>
22750 <para>
22751 <token>SOME</token> is a synonym for <token>ANY</token>.
22752 </para>
22753 </sect2>
22755 <sect2>
22756 <title><literal>ALL</literal> (array)</title>
22758 <synopsis>
22759 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
22760 </synopsis>
22762 <para>
22763 The right-hand side is a parenthesized expression, which must yield an
22764 array value.
22765 The left-hand expression
22766 is evaluated and compared to each element of the array using the
22767 given <replaceable>operator</replaceable>, which must yield a Boolean
22768 result.
22769 The result of <token>ALL</token> is <quote>true</quote> if all comparisons yield true
22770 (including the case where the array has zero elements).
22771 The result is <quote>false</quote> if any false result is found.
22772 </para>
22774 <para>
22775 If the array expression yields a null array, the result of
22776 <token>ALL</token> will be null. If the left-hand expression yields null,
22777 the result of <token>ALL</token> is ordinarily null (though a non-strict
22778 comparison operator could possibly yield a different result).
22779 Also, if the right-hand array contains any null elements and no false
22780 comparison result is obtained, the result of <token>ALL</token>
22781 will be null, not true (again, assuming a strict comparison operator).
22782 This is in accordance with SQL's normal rules for Boolean combinations
22783 of null values.
22784 </para>
22785 </sect2>
22787 <sect2 id="row-wise-comparison">
22788 <title>Row Constructor Comparison</title>
22790 <synopsis>
22791 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
22792 </synopsis>
22794 <para>
22795 Each side is a row constructor,
22796 as described in <xref linkend="sql-syntax-row-constructors"/>.
22797 The two row values must have the same number of fields.
22798 Each side is evaluated and they are compared row-wise. Row constructor
22799 comparisons are allowed when the <replaceable>operator</replaceable> is
22800 <literal>=</literal>,
22801 <literal>&lt;&gt;</literal>,
22802 <literal>&lt;</literal>,
22803 <literal>&lt;=</literal>,
22804 <literal>&gt;</literal> or
22805 <literal>&gt;=</literal>.
22806 Every row element must be of a type which has a default B-tree operator
22807 class or the attempted comparison may generate an error.
22808 </para>
22810 <note>
22811 <para>
22812 Errors related to the number or types of elements might not occur if
22813 the comparison is resolved using earlier columns.
22814 </para>
22815 </note>
22817 <para>
22818 The <literal>=</literal> and <literal>&lt;&gt;</literal> cases work slightly differently
22819 from the others. Two rows are considered
22820 equal if all their corresponding members are non-null and equal; the rows
22821 are unequal if any corresponding members are non-null and unequal;
22822 otherwise the result of the row comparison is unknown (null).
22823 </para>
22825 <para>
22826 For the <literal>&lt;</literal>, <literal>&lt;=</literal>, <literal>&gt;</literal> and
22827 <literal>&gt;=</literal> cases, the row elements are compared left-to-right,
22828 stopping as soon as an unequal or null pair of elements is found.
22829 If either of this pair of elements is null, the result of the
22830 row comparison is unknown (null); otherwise comparison of this pair
22831 of elements determines the result. For example,
22832 <literal>ROW(1,2,NULL) &lt; ROW(1,3,0)</literal>
22833 yields true, not null, because the third pair of elements are not
22834 considered.
22835 </para>
22837 <note>
22838 <para>
22839 Prior to <productname>PostgreSQL</productname> 8.2, the
22840 <literal>&lt;</literal>, <literal>&lt;=</literal>, <literal>&gt;</literal> and <literal>&gt;=</literal>
22841 cases were not handled per SQL specification. A comparison like
22842 <literal>ROW(a,b) &lt; ROW(c,d)</literal>
22843 was implemented as
22844 <literal>a &lt; c AND b &lt; d</literal>
22845 whereas the correct behavior is equivalent to
22846 <literal>a &lt; c OR (a = c AND b &lt; d)</literal>.
22847 </para>
22848 </note>
22850 <synopsis>
22851 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
22852 </synopsis>
22854 <para>
22855 This construct is similar to a <literal>&lt;&gt;</literal> row comparison,
22856 but it does not yield null for null inputs. Instead, any null value is
22857 considered unequal to (distinct from) any non-null value, and any two
22858 nulls are considered equal (not distinct). Thus the result will
22859 either be true or false, never null.
22860 </para>
22862 <synopsis>
22863 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
22864 </synopsis>
22866 <para>
22867 This construct is similar to a <literal>=</literal> row comparison,
22868 but it does not yield null for null inputs. Instead, any null value is
22869 considered unequal to (distinct from) any non-null value, and any two
22870 nulls are considered equal (not distinct). Thus the result will always
22871 be either true or false, never null.
22872 </para>
22874 </sect2>
22876 <sect2 id="composite-type-comparison">
22877 <title>Composite Type Comparison</title>
22879 <synopsis>
22880 <replaceable>record</replaceable> <replaceable>operator</replaceable> <replaceable>record</replaceable>
22881 </synopsis>
22883 <para>
22884 The SQL specification requires row-wise comparison to return NULL if the
22885 result depends on comparing two NULL values or a NULL and a non-NULL.
22886 <productname>PostgreSQL</productname> does this only when comparing the
22887 results of two row constructors (as in
22888 <xref linkend="row-wise-comparison"/>) or comparing a row constructor
22889 to the output of a subquery (as in <xref linkend="functions-subquery"/>).
22890 In other contexts where two composite-type values are compared, two
22891 NULL field values are considered equal, and a NULL is considered larger
22892 than a non-NULL. This is necessary in order to have consistent sorting
22893 and indexing behavior for composite types.
22894 </para>
22896 <para>
22897 Each side is evaluated and they are compared row-wise. Composite type
22898 comparisons are allowed when the <replaceable>operator</replaceable> is
22899 <literal>=</literal>,
22900 <literal>&lt;&gt;</literal>,
22901 <literal>&lt;</literal>,
22902 <literal>&lt;=</literal>,
22903 <literal>&gt;</literal> or
22904 <literal>&gt;=</literal>,
22905 or has semantics similar to one of these. (To be specific, an operator
22906 can be a row comparison operator if it is a member of a B-tree operator
22907 class, or is the negator of the <literal>=</literal> member of a B-tree operator
22908 class.) The default behavior of the above operators is the same as for
22909 <literal>IS [ NOT ] DISTINCT FROM</literal> for row constructors (see
22910 <xref linkend="row-wise-comparison"/>).
22911 </para>
22913 <para>
22914 To support matching of rows which include elements without a default
22915 B-tree operator class, the following operators are defined for composite
22916 type comparison:
22917 <literal>*=</literal>,
22918 <literal>*&lt;&gt;</literal>,
22919 <literal>*&lt;</literal>,
22920 <literal>*&lt;=</literal>,
22921 <literal>*&gt;</literal>, and
22922 <literal>*&gt;=</literal>.
22923 These operators compare the internal binary representation of the two
22924 rows. Two rows might have a different binary representation even
22925 though comparisons of the two rows with the equality operator is true.
22926 The ordering of rows under these comparison operators is deterministic
22927 but not otherwise meaningful. These operators are used internally
22928 for materialized views and might be useful for other specialized
22929 purposes such as replication and B-Tree deduplication (see <xref
22930 linkend="btree-deduplication"/>). They are not intended to be
22931 generally useful for writing queries, though.
22932 </para>
22933 </sect2>
22934 </sect1>
22936 <sect1 id="functions-srf">
22937 <title>Set Returning Functions</title>
22939 <indexterm zone="functions-srf">
22940 <primary>set returning functions</primary>
22941 <secondary>functions</secondary>
22942 </indexterm>
22944 <para>
22945 This section describes functions that possibly return more than one row.
22946 The most widely used functions in this class are series generating
22947 functions, as detailed in <xref linkend="functions-srf-series"/> and
22948 <xref linkend="functions-srf-subscripts"/>. Other, more specialized
22949 set-returning functions are described elsewhere in this manual.
22950 See <xref linkend="queries-tablefunctions"/> for ways to combine multiple
22951 set-returning functions.
22952 </para>
22954 <table id="functions-srf-series">
22955 <title>Series Generating Functions</title>
22956 <tgroup cols="1">
22957 <thead>
22958 <row>
22959 <entry role="func_table_entry"><para role="func_signature">
22960 Function
22961 </para>
22962 <para>
22963 Description
22964 </para></entry>
22965 </row>
22966 </thead>
22968 <tbody>
22969 <row>
22970 <entry role="func_table_entry"><para role="func_signature">
22971 <indexterm>
22972 <primary>generate_series</primary>
22973 </indexterm>
22974 <function>generate_series</function> ( <parameter>start</parameter> <type>integer</type>, <parameter>stop</parameter> <type>integer</type> <optional>, <parameter>step</parameter> <type>integer</type> </optional> )
22975 <returnvalue>setof integer</returnvalue>
22976 </para>
22977 <para role="func_signature">
22978 <function>generate_series</function> ( <parameter>start</parameter> <type>bigint</type>, <parameter>stop</parameter> <type>bigint</type> <optional>, <parameter>step</parameter> <type>bigint</type> </optional> )
22979 <returnvalue>setof bigint</returnvalue>
22980 </para>
22981 <para role="func_signature">
22982 <function>generate_series</function> ( <parameter>start</parameter> <type>numeric</type>, <parameter>stop</parameter> <type>numeric</type> <optional>, <parameter>step</parameter> <type>numeric</type> </optional> )
22983 <returnvalue>setof numeric</returnvalue>
22984 </para>
22985 <para>
22986 Generates a series of values from <parameter>start</parameter>
22987 to <parameter>stop</parameter>, with a step size
22988 of <parameter>step</parameter>. <parameter>step</parameter>
22989 defaults to 1.
22990 </para></entry>
22991 </row>
22993 <row>
22994 <entry role="func_table_entry"><para role="func_signature">
22995 <function>generate_series</function> ( <parameter>start</parameter> <type>timestamp</type>, <parameter>stop</parameter> <type>timestamp</type>, <parameter>step</parameter> <type>interval</type> )
22996 <returnvalue>setof timestamp</returnvalue>
22997 </para>
22998 <para role="func_signature">
22999 <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> )
23000 <returnvalue>setof timestamp with time zone</returnvalue>
23001 </para>
23002 <para>
23003 Generates a series of values from <parameter>start</parameter>
23004 to <parameter>stop</parameter>, with a step size
23005 of <parameter>step</parameter>.
23006 </para></entry>
23007 </row>
23008 </tbody>
23009 </tgroup>
23010 </table>
23012 <para>
23013 When <parameter>step</parameter> is positive, zero rows are returned if
23014 <parameter>start</parameter> is greater than <parameter>stop</parameter>.
23015 Conversely, when <parameter>step</parameter> is negative, zero rows are
23016 returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
23017 Zero rows are also returned if any input is <literal>NULL</literal>.
23018 It is an error
23019 for <parameter>step</parameter> to be zero. Some examples follow:
23020 <programlisting>
23021 SELECT * FROM generate_series(2,4);
23022 generate_series
23023 -----------------
23027 (3 rows)
23029 SELECT * FROM generate_series(5,1,-2);
23030 generate_series
23031 -----------------
23035 (3 rows)
23037 SELECT * FROM generate_series(4,3);
23038 generate_series
23039 -----------------
23040 (0 rows)
23042 SELECT generate_series(1.1, 4, 1.3);
23043 generate_series
23044 -----------------
23048 (3 rows)
23050 -- this example relies on the date-plus-integer operator:
23051 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
23052 dates
23053 ------------
23054 2004-02-05
23055 2004-02-12
23056 2004-02-19
23057 (3 rows)
23059 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
23060 '2008-03-04 12:00', '10 hours');
23061 generate_series
23062 ---------------------
23063 2008-03-01 00:00:00
23064 2008-03-01 10:00:00
23065 2008-03-01 20:00:00
23066 2008-03-02 06:00:00
23067 2008-03-02 16:00:00
23068 2008-03-03 02:00:00
23069 2008-03-03 12:00:00
23070 2008-03-03 22:00:00
23071 2008-03-04 08:00:00
23072 (9 rows)
23073 </programlisting>
23074 </para>
23076 <table id="functions-srf-subscripts">
23077 <title>Subscript Generating Functions</title>
23078 <tgroup cols="1">
23079 <thead>
23080 <row>
23081 <entry role="func_table_entry"><para role="func_signature">
23082 Function
23083 </para>
23084 <para>
23085 Description
23086 </para></entry>
23087 </row>
23088 </thead>
23090 <tbody>
23091 <row>
23092 <entry role="func_table_entry"><para role="func_signature">
23093 <indexterm>
23094 <primary>generate_subscripts</primary>
23095 </indexterm>
23096 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type> )
23097 <returnvalue>setof integer</returnvalue>
23098 </para>
23099 <para>
23100 Generates a series comprising the valid subscripts of
23101 the <parameter>dim</parameter>'th dimension of the given array.
23102 </para></entry>
23103 </row>
23105 <row>
23106 <entry role="func_table_entry"><para role="func_signature">
23107 <function>generate_subscripts</function> ( <parameter>array</parameter> <type>anyarray</type>, <parameter>dim</parameter> <type>integer</type>, <parameter>reverse</parameter> <type>boolean</type> )
23108 <returnvalue>setof integer</returnvalue>
23109 </para>
23110 <para>
23111 Generates a series comprising the valid subscripts of
23112 the <parameter>dim</parameter>'th dimension of the given array.
23113 When <parameter>reverse</parameter> is true, returns the series in
23114 reverse order.
23115 </para></entry>
23116 </row>
23117 </tbody>
23118 </tgroup>
23119 </table>
23121 <para>
23122 <function>generate_subscripts</function> is a convenience function that generates
23123 the set of valid subscripts for the specified dimension of the given
23124 array.
23125 Zero rows are returned for arrays that do not have the requested dimension,
23126 or if any input is <literal>NULL</literal>.
23127 Some examples follow:
23128 <programlisting>
23129 -- basic usage:
23130 SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
23137 (4 rows)
23139 -- presenting an array, the subscript and the subscripted
23140 -- value requires a subquery:
23141 SELECT * FROM arrays;
23143 --------------------
23144 {-1,-2}
23145 {100,200,300}
23146 (2 rows)
23148 SELECT a AS array, s AS subscript, a[s] AS value
23149 FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
23150 array | subscript | value
23151 ---------------+-----------+-------
23152 {-1,-2} | 1 | -1
23153 {-1,-2} | 2 | -2
23154 {100,200,300} | 1 | 100
23155 {100,200,300} | 2 | 200
23156 {100,200,300} | 3 | 300
23157 (5 rows)
23159 -- unnest a 2D array:
23160 CREATE OR REPLACE FUNCTION unnest2(anyarray)
23161 RETURNS SETOF anyelement AS $$
23162 select $1[i][j]
23163 from generate_subscripts($1,1) g1(i),
23164 generate_subscripts($1,2) g2(j);
23165 $$ LANGUAGE sql IMMUTABLE;
23166 CREATE FUNCTION
23167 SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
23168 unnest2
23169 ---------
23174 (4 rows)
23175 </programlisting>
23176 </para>
23178 <indexterm>
23179 <primary>ordinality</primary>
23180 </indexterm>
23182 <para>
23183 When a function in the <literal>FROM</literal> clause is suffixed
23184 by <literal>WITH ORDINALITY</literal>, a <type>bigint</type> column is
23185 appended to the function's output column(s), which starts from 1 and
23186 increments by 1 for each row of the function's output.
23187 This is most useful in the case of set returning
23188 functions such as <function>unnest()</function>.
23190 <programlisting>
23191 -- set returning function WITH ORDINALITY:
23192 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
23193 ls | n
23194 -----------------+----
23195 pg_serial | 1
23196 pg_twophase | 2
23197 postmaster.opts | 3
23198 pg_notify | 4
23199 postgresql.conf | 5
23200 pg_tblspc | 6
23201 logfile | 7
23202 base | 8
23203 postmaster.pid | 9
23204 pg_ident.conf | 10
23205 global | 11
23206 pg_xact | 12
23207 pg_snapshots | 13
23208 pg_multixact | 14
23209 PG_VERSION | 15
23210 pg_wal | 16
23211 pg_hba.conf | 17
23212 pg_stat_tmp | 18
23213 pg_subtrans | 19
23214 (19 rows)
23215 </programlisting>
23216 </para>
23218 </sect1>
23220 <sect1 id="functions-info">
23221 <title>System Information Functions and Operators</title>
23223 <para>
23224 <xref linkend="functions-info-session-table"/> shows several
23225 functions that extract session and system information.
23226 </para>
23228 <para>
23229 In addition to the functions listed in this section, there are a number of
23230 functions related to the statistics system that also provide system
23231 information. See <xref linkend="monitoring-stats-views"/> for more
23232 information.
23233 </para>
23235 <table id="functions-info-session-table">
23236 <title>Session Information Functions</title>
23237 <tgroup cols="1">
23238 <thead>
23239 <row>
23240 <entry role="func_table_entry"><para role="func_signature">
23241 Function
23242 </para>
23243 <para>
23244 Description
23245 </para></entry>
23246 </row>
23247 </thead>
23249 <tbody>
23250 <row>
23251 <entry role="func_table_entry"><para role="func_signature">
23252 <indexterm>
23253 <primary>current_catalog</primary>
23254 </indexterm>
23255 <function>current_catalog</function>
23256 <returnvalue>name</returnvalue>
23257 </para>
23258 <para role="func_signature">
23259 <indexterm>
23260 <primary>current_database</primary>
23261 </indexterm>
23262 <function>current_database</function> ()
23263 <returnvalue>name</returnvalue>
23264 </para>
23265 <para>
23266 Returns the name of the current database. (Databases are
23267 called <quote>catalogs</quote> in the SQL standard,
23268 so <function>current_catalog</function> is the standard's
23269 spelling.)
23270 </para></entry>
23271 </row>
23273 <row>
23274 <entry role="func_table_entry"><para role="func_signature">
23275 <indexterm>
23276 <primary>current_query</primary>
23277 </indexterm>
23278 <function>current_query</function> ()
23279 <returnvalue>text</returnvalue>
23280 </para>
23281 <para>
23282 Returns the text of the currently executing query, as submitted
23283 by the client (which might contain more than one statement).
23284 </para></entry>
23285 </row>
23287 <row>
23288 <entry role="func_table_entry"><para role="func_signature">
23289 <indexterm>
23290 <primary>current_role</primary>
23291 </indexterm>
23292 <function>current_role</function>
23293 <returnvalue>name</returnvalue>
23294 </para>
23295 <para>
23296 This is equivalent to <function>current_user</function>.
23297 </para></entry>
23298 </row>
23300 <row>
23301 <entry role="func_table_entry"><para role="func_signature">
23302 <indexterm>
23303 <primary>current_schema</primary>
23304 </indexterm>
23305 <indexterm>
23306 <primary>schema</primary>
23307 <secondary>current</secondary>
23308 </indexterm>
23309 <function>current_schema</function>
23310 <returnvalue>name</returnvalue>
23311 </para>
23312 <para role="func_signature">
23313 <function>current_schema</function> ()
23314 <returnvalue>name</returnvalue>
23315 </para>
23316 <para>
23317 Returns the name of the schema that is first in the search path (or a
23318 null value if the search path is empty). This is the schema that will
23319 be used for any tables or other named objects that are created without
23320 specifying a target schema.
23321 </para></entry>
23322 </row>
23324 <row>
23325 <entry role="func_table_entry"><para role="func_signature">
23326 <indexterm>
23327 <primary>current_schemas</primary>
23328 </indexterm>
23329 <indexterm>
23330 <primary>search path</primary>
23331 <secondary>current</secondary>
23332 </indexterm>
23333 <function>current_schemas</function> ( <parameter>include_implicit</parameter> <type>boolean</type> )
23334 <returnvalue>name[]</returnvalue>
23335 </para>
23336 <para>
23337 Returns an array of the names of all schemas presently in the
23338 effective search path, in their priority order. (Items in the current
23339 <xref linkend="guc-search-path"/> setting that do not correspond to
23340 existing, searchable schemas are omitted.) If the Boolean argument
23341 is <literal>true</literal>, then implicitly-searched system schemas
23342 such as <literal>pg_catalog</literal> are included in the result.
23343 </para></entry>
23344 </row>
23346 <row>
23347 <entry role="func_table_entry"><para role="func_signature">
23348 <indexterm>
23349 <primary>current_user</primary>
23350 </indexterm>
23351 <indexterm>
23352 <primary>user</primary>
23353 <secondary>current</secondary>
23354 </indexterm>
23355 <function>current_user</function>
23356 <returnvalue>name</returnvalue>
23357 </para>
23358 <para>
23359 Returns the user name of the current execution context.
23360 </para></entry>
23361 </row>
23363 <row>
23364 <entry role="func_table_entry"><para role="func_signature">
23365 <indexterm>
23366 <primary>inet_client_addr</primary>
23367 </indexterm>
23368 <function>inet_client_addr</function> ()
23369 <returnvalue>inet</returnvalue>
23370 </para>
23371 <para>
23372 Returns the IP address of the current client,
23373 or <literal>NULL</literal> if the current connection is via a
23374 Unix-domain socket.
23375 </para></entry>
23376 </row>
23378 <row>
23379 <entry role="func_table_entry"><para role="func_signature">
23380 <indexterm>
23381 <primary>inet_client_port</primary>
23382 </indexterm>
23383 <function>inet_client_port</function> ()
23384 <returnvalue>integer</returnvalue>
23385 </para>
23386 <para>
23387 Returns the IP port number of the current client,
23388 or <literal>NULL</literal> if the current connection is via a
23389 Unix-domain socket.
23390 </para></entry>
23391 </row>
23393 <row>
23394 <entry role="func_table_entry"><para role="func_signature">
23395 <indexterm>
23396 <primary>inet_server_addr</primary>
23397 </indexterm>
23398 <function>inet_server_addr</function> ()
23399 <returnvalue>inet</returnvalue>
23400 </para>
23401 <para>
23402 Returns the IP address on which the server accepted the current
23403 connection,
23404 or <literal>NULL</literal> if the current connection is via a
23405 Unix-domain socket.
23406 </para></entry>
23407 </row>
23409 <row>
23410 <entry role="func_table_entry"><para role="func_signature">
23411 <indexterm>
23412 <primary>inet_server_port</primary>
23413 </indexterm>
23414 <function>inet_server_port</function> ()
23415 <returnvalue>integer</returnvalue>
23416 </para>
23417 <para>
23418 Returns the IP port number on which the server accepted the current
23419 connection,
23420 or <literal>NULL</literal> if the current connection is via a
23421 Unix-domain socket.
23422 </para></entry>
23423 </row>
23425 <row>
23426 <entry role="func_table_entry"><para role="func_signature">
23427 <indexterm>
23428 <primary>pg_backend_pid</primary>
23429 </indexterm>
23430 <function>pg_backend_pid</function> ()
23431 <returnvalue>integer</returnvalue>
23432 </para>
23433 <para>
23434 Returns the process ID of the server process attached to the current
23435 session.
23436 </para></entry>
23437 </row>
23439 <row>
23440 <entry role="func_table_entry"><para role="func_signature">
23441 <indexterm>
23442 <primary>pg_blocking_pids</primary>
23443 </indexterm>
23444 <function>pg_blocking_pids</function> ( <type>integer</type> )
23445 <returnvalue>integer[]</returnvalue>
23446 </para>
23447 <para>
23448 Returns an array of the process ID(s) of the sessions that are
23449 blocking the server process with the specified process ID from
23450 acquiring a lock, or an empty array if there is no such server process
23451 or it is not blocked.
23452 </para>
23453 <para>
23454 One server process blocks another if it either holds a lock that
23455 conflicts with the blocked process's lock request (hard block), or is
23456 waiting for a lock that would conflict with the blocked process's lock
23457 request and is ahead of it in the wait queue (soft block). When using
23458 parallel queries the result always lists client-visible process IDs
23459 (that is, <function>pg_backend_pid</function> results) even if the
23460 actual lock is held or awaited by a child worker process. As a result
23461 of that, there may be duplicated PIDs in the result. Also note that
23462 when a prepared transaction holds a conflicting lock, it will be
23463 represented by a zero process ID.
23464 </para>
23465 <para>
23466 Frequent calls to this function could have some impact on database
23467 performance, because it needs exclusive access to the lock manager's
23468 shared state for a short time.
23469 </para></entry>
23470 </row>
23472 <row>
23473 <entry role="func_table_entry"><para role="func_signature">
23474 <indexterm>
23475 <primary>pg_conf_load_time</primary>
23476 </indexterm>
23477 <function>pg_conf_load_time</function> ()
23478 <returnvalue>timestamp with time zone</returnvalue>
23479 </para>
23480 <para>
23481 Returns the time when the server configuration files were last loaded.
23482 If the current session was alive at the time, this will be the time
23483 when the session itself re-read the configuration files (so the
23484 reading will vary a little in different sessions). Otherwise it is
23485 the time when the postmaster process re-read the configuration files.
23486 </para></entry>
23487 </row>
23489 <row>
23490 <entry role="func_table_entry"><para role="func_signature">
23491 <indexterm>
23492 <primary>pg_current_logfile</primary>
23493 </indexterm>
23494 <indexterm>
23495 <primary>Logging</primary>
23496 <secondary>pg_current_logfile function</secondary>
23497 </indexterm>
23498 <indexterm>
23499 <primary>current_logfiles</primary>
23500 <secondary>and the pg_current_logfile function</secondary>
23501 </indexterm>
23502 <indexterm>
23503 <primary>Logging</primary>
23504 <secondary>current_logfiles file and the pg_current_logfile
23505 function</secondary>
23506 </indexterm>
23507 <function>pg_current_logfile</function> ( <optional> <type>text</type> </optional> )
23508 <returnvalue>text</returnvalue>
23509 </para>
23510 <para>
23511 Returns the path name of the log file currently in use by the logging
23512 collector. The path includes the <xref linkend="guc-log-directory"/>
23513 directory and the individual log file name. The result
23514 is <literal>NULL</literal> if the logging collector is disabled.
23515 When multiple log files exist, each in a different
23516 format, <function>pg_current_logfile</function> without an argument
23517 returns the path of the file having the first format found in the
23518 ordered list: <literal>stderr</literal>,
23519 <literal>csvlog</literal>, <literal>jsonlog</literal>.
23520 <literal>NULL</literal> is returned if no log file has any of these
23521 formats.
23522 To request information about a specific log file format, supply
23523 either <literal>csvlog</literal>, <literal>jsonlog</literal> or
23524 <literal>stderr</literal> as the
23525 value of the optional parameter. The result is <literal>NULL</literal>
23526 if the log format requested is not configured in
23527 <xref linkend="guc-log-destination"/>.
23528 The result reflects the contents of
23529 the <filename>current_logfiles</filename> file.
23530 </para></entry>
23531 </row>
23533 <row>
23534 <entry role="func_table_entry"><para role="func_signature">
23535 <indexterm>
23536 <primary>pg_my_temp_schema</primary>
23537 </indexterm>
23538 <function>pg_my_temp_schema</function> ()
23539 <returnvalue>oid</returnvalue>
23540 </para>
23541 <para>
23542 Returns the OID of the current session's temporary schema, or zero if
23543 it has none (because it has not created any temporary tables).
23544 </para></entry>
23545 </row>
23547 <row>
23548 <entry role="func_table_entry"><para role="func_signature">
23549 <indexterm>
23550 <primary>pg_is_other_temp_schema</primary>
23551 </indexterm>
23552 <function>pg_is_other_temp_schema</function> ( <type>oid</type> )
23553 <returnvalue>boolean</returnvalue>
23554 </para>
23555 <para>
23556 Returns true if the given OID is the OID of another session's
23557 temporary schema. (This can be useful, for example, to exclude other
23558 sessions' temporary tables from a catalog display.)
23559 </para></entry>
23560 </row>
23562 <row>
23563 <entry role="func_table_entry"><para role="func_signature">
23564 <indexterm>
23565 <primary>pg_jit_available</primary>
23566 </indexterm>
23567 <function>pg_jit_available</function> ()
23568 <returnvalue>boolean</returnvalue>
23569 </para>
23570 <para>
23571 Returns true if a <acronym>JIT</acronym> compiler extension is
23572 available (see <xref linkend="jit"/>) and the
23573 <xref linkend="guc-jit"/> configuration parameter is set to
23574 <literal>on</literal>.
23575 </para></entry>
23576 </row>
23578 <row>
23579 <entry role="func_table_entry"><para role="func_signature">
23580 <indexterm>
23581 <primary>pg_listening_channels</primary>
23582 </indexterm>
23583 <function>pg_listening_channels</function> ()
23584 <returnvalue>setof text</returnvalue>
23585 </para>
23586 <para>
23587 Returns the set of names of asynchronous notification channels that
23588 the current session is listening to.
23589 </para></entry>
23590 </row>
23592 <row>
23593 <entry role="func_table_entry"><para role="func_signature">
23594 <indexterm>
23595 <primary>pg_notification_queue_usage</primary>
23596 </indexterm>
23597 <function>pg_notification_queue_usage</function> ()
23598 <returnvalue>double precision</returnvalue>
23599 </para>
23600 <para>
23601 Returns the fraction (0&ndash;1) of the asynchronous notification
23602 queue's maximum size that is currently occupied by notifications that
23603 are waiting to be processed.
23604 See <xref linkend="sql-listen"/> and <xref linkend="sql-notify"/>
23605 for more information.
23606 </para></entry>
23607 </row>
23609 <row>
23610 <entry role="func_table_entry"><para role="func_signature">
23611 <indexterm>
23612 <primary>pg_postmaster_start_time</primary>
23613 </indexterm>
23614 <function>pg_postmaster_start_time</function> ()
23615 <returnvalue>timestamp with time zone</returnvalue>
23616 </para>
23617 <para>
23618 Returns the time when the server started.
23619 </para></entry>
23620 </row>
23622 <row>
23623 <entry role="func_table_entry"><para role="func_signature">
23624 <indexterm>
23625 <primary>pg_safe_snapshot_blocking_pids</primary>
23626 </indexterm>
23627 <function>pg_safe_snapshot_blocking_pids</function> ( <type>integer</type> )
23628 <returnvalue>integer[]</returnvalue>
23629 </para>
23630 <para>
23631 Returns an array of the process ID(s) of the sessions that are blocking
23632 the server process with the specified process ID from acquiring a safe
23633 snapshot, or an empty array if there is no such server process or it
23634 is not blocked.
23635 </para>
23636 <para>
23637 A session running a <literal>SERIALIZABLE</literal> transaction blocks
23638 a <literal>SERIALIZABLE READ ONLY DEFERRABLE</literal> transaction
23639 from acquiring a snapshot until the latter determines that it is safe
23640 to avoid taking any predicate locks. See
23641 <xref linkend="xact-serializable"/> for more information about
23642 serializable and deferrable transactions.
23643 </para>
23644 <para>
23645 Frequent calls to this function could have some impact on database
23646 performance, because it needs access to the predicate lock manager's
23647 shared state for a short time.
23648 </para></entry>
23649 </row>
23651 <row>
23652 <entry role="func_table_entry"><para role="func_signature">
23653 <indexterm>
23654 <primary>pg_trigger_depth</primary>
23655 </indexterm>
23656 <function>pg_trigger_depth</function> ()
23657 <returnvalue>integer</returnvalue>
23658 </para>
23659 <para>
23660 Returns the current nesting level
23661 of <productname>PostgreSQL</productname> triggers (0 if not called,
23662 directly or indirectly, from inside a trigger).
23663 </para></entry>
23664 </row>
23666 <row>
23667 <entry role="func_table_entry"><para role="func_signature">
23668 <indexterm>
23669 <primary>session_user</primary>
23670 </indexterm>
23671 <function>session_user</function>
23672 <returnvalue>name</returnvalue>
23673 </para>
23674 <para>
23675 Returns the session user's name.
23676 </para></entry>
23677 </row>
23679 <row>
23680 <entry role="func_table_entry"><para role="func_signature">
23681 <indexterm>
23682 <primary>user</primary>
23683 </indexterm>
23684 <function>user</function>
23685 <returnvalue>name</returnvalue>
23686 </para>
23687 <para>
23688 This is equivalent to <function>current_user</function>.
23689 </para></entry>
23690 </row>
23692 <row>
23693 <entry role="func_table_entry"><para role="func_signature">
23694 <indexterm>
23695 <primary>version</primary>
23696 </indexterm>
23697 <function>version</function> ()
23698 <returnvalue>text</returnvalue>
23699 </para>
23700 <para>
23701 Returns a string describing the <productname>PostgreSQL</productname>
23702 server's version. You can also get this information from
23703 <xref linkend="guc-server-version"/>, or for a machine-readable
23704 version use <xref linkend="guc-server-version-num"/>. Software
23705 developers should use <varname>server_version_num</varname> (available
23706 since 8.2) or <xref linkend="libpq-PQserverVersion"/> instead of
23707 parsing the text version.
23708 </para></entry>
23709 </row>
23710 </tbody>
23711 </tgroup>
23712 </table>
23714 <note>
23715 <para>
23716 <function>current_catalog</function>,
23717 <function>current_role</function>,
23718 <function>current_schema</function>,
23719 <function>current_user</function>,
23720 <function>session_user</function>,
23721 and <function>user</function> have special syntactic status
23722 in <acronym>SQL</acronym>: they must be called without trailing
23723 parentheses. In PostgreSQL, parentheses can optionally be used with
23724 <function>current_schema</function>, but not with the others.
23725 </para>
23726 </note>
23728 <para>
23729 The <function>session_user</function> is normally the user who initiated
23730 the current database connection; but superusers can change this setting
23731 with <xref linkend="sql-set-session-authorization"/>.
23732 The <function>current_user</function> is the user identifier
23733 that is applicable for permission checking. Normally it is equal
23734 to the session user, but it can be changed with
23735 <xref linkend="sql-set-role"/>.
23736 It also changes during the execution of
23737 functions with the attribute <literal>SECURITY DEFINER</literal>.
23738 In Unix parlance, the session user is the <quote>real user</quote> and
23739 the current user is the <quote>effective user</quote>.
23740 <function>current_role</function> and <function>user</function> are
23741 synonyms for <function>current_user</function>. (The SQL standard draws
23742 a distinction between <function>current_role</function>
23743 and <function>current_user</function>, but <productname>PostgreSQL</productname>
23744 does not, since it unifies users and roles into a single kind of entity.)
23745 </para>
23747 <indexterm>
23748 <primary>privilege</primary>
23749 <secondary>querying</secondary>
23750 </indexterm>
23752 <para>
23753 <xref linkend="functions-info-access-table"/> lists functions that
23754 allow querying object access privileges programmatically.
23755 (See <xref linkend="ddl-priv"/> for more information about
23756 privileges.)
23757 In these functions, the user whose privileges are being inquired about
23758 can be specified by name or by OID
23759 (<structname>pg_authid</structname>.<structfield>oid</structfield>), or if
23760 the name is given as <literal>public</literal> then the privileges of the
23761 PUBLIC pseudo-role are checked. Also, the <parameter>user</parameter>
23762 argument can be omitted entirely, in which case
23763 the <function>current_user</function> is assumed.
23764 The object that is being inquired about can be specified either by name or
23765 by OID, too. When specifying by name, a schema name can be included if
23766 relevant.
23767 The access privilege of interest is specified by a text string, which must
23768 evaluate to one of the appropriate privilege keywords for the object's type
23769 (e.g., <literal>SELECT</literal>). Optionally, <literal>WITH GRANT
23770 OPTION</literal> can be added to a privilege type to test whether the
23771 privilege is held with grant option. Also, multiple privilege types can be
23772 listed separated by commas, in which case the result will be true if any of
23773 the listed privileges is held. (Case of the privilege string is not
23774 significant, and extra whitespace is allowed between but not within
23775 privilege names.)
23776 Some examples:
23777 <programlisting>
23778 SELECT has_table_privilege('myschema.mytable', 'select');
23779 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
23780 </programlisting>
23781 </para>
23783 <table id="functions-info-access-table">
23784 <title>Access Privilege Inquiry Functions</title>
23785 <tgroup cols="1">
23786 <thead>
23787 <row>
23788 <entry role="func_table_entry"><para role="func_signature">
23789 Function
23790 </para>
23791 <para>
23792 Description
23793 </para></entry>
23794 </row>
23795 </thead>
23797 <tbody>
23798 <row>
23799 <entry role="func_table_entry"><para role="func_signature">
23800 <indexterm>
23801 <primary>has_any_column_privilege</primary>
23802 </indexterm>
23803 <function>has_any_column_privilege</function> (
23804 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23805 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
23806 <parameter>privilege</parameter> <type>text</type> )
23807 <returnvalue>boolean</returnvalue>
23808 </para>
23809 <para>
23810 Does user have privilege for any column of table?
23811 This succeeds either if the privilege is held for the whole table, or
23812 if there is a column-level grant of the privilege for at least one
23813 column.
23814 Allowable privilege types are
23815 <literal>SELECT</literal>, <literal>INSERT</literal>,
23816 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
23817 </para></entry>
23818 </row>
23820 <row>
23821 <entry role="func_table_entry"><para role="func_signature">
23822 <indexterm>
23823 <primary>has_column_privilege</primary>
23824 </indexterm>
23825 <function>has_column_privilege</function> (
23826 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23827 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
23828 <parameter>column</parameter> <type>text</type> or <type>smallint</type>,
23829 <parameter>privilege</parameter> <type>text</type> )
23830 <returnvalue>boolean</returnvalue>
23831 </para>
23832 <para>
23833 Does user have privilege for the specified table column?
23834 This succeeds either if the privilege is held for the whole table, or
23835 if there is a column-level grant of the privilege for the column.
23836 The column can be specified by name or by attribute number
23837 (<structname>pg_attribute</structname>.<structfield>attnum</structfield>).
23838 Allowable privilege types are
23839 <literal>SELECT</literal>, <literal>INSERT</literal>,
23840 <literal>UPDATE</literal>, and <literal>REFERENCES</literal>.
23841 </para></entry>
23842 </row>
23844 <row>
23845 <entry role="func_table_entry"><para role="func_signature">
23846 <indexterm>
23847 <primary>has_database_privilege</primary>
23848 </indexterm>
23849 <function>has_database_privilege</function> (
23850 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23851 <parameter>database</parameter> <type>text</type> or <type>oid</type>,
23852 <parameter>privilege</parameter> <type>text</type> )
23853 <returnvalue>boolean</returnvalue>
23854 </para>
23855 <para>
23856 Does user have privilege for database?
23857 Allowable privilege types are
23858 <literal>CREATE</literal>,
23859 <literal>CONNECT</literal>,
23860 <literal>TEMPORARY</literal>, and
23861 <literal>TEMP</literal> (which is equivalent to
23862 <literal>TEMPORARY</literal>).
23863 </para></entry>
23864 </row>
23866 <row>
23867 <entry role="func_table_entry"><para role="func_signature">
23868 <indexterm>
23869 <primary>has_foreign_data_wrapper_privilege</primary>
23870 </indexterm>
23871 <function>has_foreign_data_wrapper_privilege</function> (
23872 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23873 <parameter>fdw</parameter> <type>text</type> or <type>oid</type>,
23874 <parameter>privilege</parameter> <type>text</type> )
23875 <returnvalue>boolean</returnvalue>
23876 </para>
23877 <para>
23878 Does user have privilege for foreign-data wrapper?
23879 The only allowable privilege type is <literal>USAGE</literal>.
23880 </para></entry>
23881 </row>
23883 <row>
23884 <entry role="func_table_entry"><para role="func_signature">
23885 <indexterm>
23886 <primary>has_function_privilege</primary>
23887 </indexterm>
23888 <function>has_function_privilege</function> (
23889 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23890 <parameter>function</parameter> <type>text</type> or <type>oid</type>,
23891 <parameter>privilege</parameter> <type>text</type> )
23892 <returnvalue>boolean</returnvalue>
23893 </para>
23894 <para>
23895 Does user have privilege for function?
23896 The only allowable privilege type is <literal>EXECUTE</literal>.
23897 </para>
23898 <para>
23899 When specifying a function by name rather than by OID, the allowed
23900 input is the same as for the <type>regprocedure</type> data type (see
23901 <xref linkend="datatype-oid"/>).
23902 An example is:
23903 <programlisting>
23904 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
23905 </programlisting>
23906 </para></entry>
23907 </row>
23909 <row>
23910 <entry role="func_table_entry"><para role="func_signature">
23911 <indexterm>
23912 <primary>has_language_privilege</primary>
23913 </indexterm>
23914 <function>has_language_privilege</function> (
23915 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23916 <parameter>language</parameter> <type>text</type> or <type>oid</type>,
23917 <parameter>privilege</parameter> <type>text</type> )
23918 <returnvalue>boolean</returnvalue>
23919 </para>
23920 <para>
23921 Does user have privilege for language?
23922 The only allowable privilege type is <literal>USAGE</literal>.
23923 </para></entry>
23924 </row>
23926 <row>
23927 <entry role="func_table_entry"><para role="func_signature">
23928 <indexterm>
23929 <primary>has_parameter_privilege</primary>
23930 </indexterm>
23931 <function>has_parameter_privilege</function> (
23932 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23933 <parameter>parameter</parameter> <type>text</type>,
23934 <parameter>privilege</parameter> <type>text</type> )
23935 <returnvalue>boolean</returnvalue>
23936 </para>
23937 <para>
23938 Does user have privilege for configuration parameter?
23939 The parameter name is case-insensitive.
23940 Allowable privilege types are <literal>SET</literal>
23941 and <literal>ALTER SYSTEM</literal>.
23942 </para></entry>
23943 </row>
23945 <row>
23946 <entry role="func_table_entry"><para role="func_signature">
23947 <indexterm>
23948 <primary>has_schema_privilege</primary>
23949 </indexterm>
23950 <function>has_schema_privilege</function> (
23951 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23952 <parameter>schema</parameter> <type>text</type> or <type>oid</type>,
23953 <parameter>privilege</parameter> <type>text</type> )
23954 <returnvalue>boolean</returnvalue>
23955 </para>
23956 <para>
23957 Does user have privilege for schema?
23958 Allowable privilege types are
23959 <literal>CREATE</literal> and
23960 <literal>USAGE</literal>.
23961 </para></entry>
23962 </row>
23964 <row>
23965 <entry role="func_table_entry"><para role="func_signature">
23966 <indexterm>
23967 <primary>has_sequence_privilege</primary>
23968 </indexterm>
23969 <function>has_sequence_privilege</function> (
23970 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23971 <parameter>sequence</parameter> <type>text</type> or <type>oid</type>,
23972 <parameter>privilege</parameter> <type>text</type> )
23973 <returnvalue>boolean</returnvalue>
23974 </para>
23975 <para>
23976 Does user have privilege for sequence?
23977 Allowable privilege types are
23978 <literal>USAGE</literal>,
23979 <literal>SELECT</literal>, and
23980 <literal>UPDATE</literal>.
23981 </para></entry>
23982 </row>
23984 <row>
23985 <entry role="func_table_entry"><para role="func_signature">
23986 <indexterm>
23987 <primary>has_server_privilege</primary>
23988 </indexterm>
23989 <function>has_server_privilege</function> (
23990 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
23991 <parameter>server</parameter> <type>text</type> or <type>oid</type>,
23992 <parameter>privilege</parameter> <type>text</type> )
23993 <returnvalue>boolean</returnvalue>
23994 </para>
23995 <para>
23996 Does user have privilege for foreign server?
23997 The only allowable privilege type is <literal>USAGE</literal>.
23998 </para></entry>
23999 </row>
24001 <row>
24002 <entry role="func_table_entry"><para role="func_signature">
24003 <indexterm>
24004 <primary>has_table_privilege</primary>
24005 </indexterm>
24006 <function>has_table_privilege</function> (
24007 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
24008 <parameter>table</parameter> <type>text</type> or <type>oid</type>,
24009 <parameter>privilege</parameter> <type>text</type> )
24010 <returnvalue>boolean</returnvalue>
24011 </para>
24012 <para>
24013 Does user have privilege for table?
24014 Allowable privilege types
24015 are <literal>SELECT</literal>, <literal>INSERT</literal>,
24016 <literal>UPDATE</literal>, <literal>DELETE</literal>,
24017 <literal>TRUNCATE</literal>, <literal>REFERENCES</literal>,
24018 and <literal>TRIGGER</literal>.
24019 </para></entry>
24020 </row>
24022 <row>
24023 <entry role="func_table_entry"><para role="func_signature">
24024 <indexterm>
24025 <primary>has_tablespace_privilege</primary>
24026 </indexterm>
24027 <function>has_tablespace_privilege</function> (
24028 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
24029 <parameter>tablespace</parameter> <type>text</type> or <type>oid</type>,
24030 <parameter>privilege</parameter> <type>text</type> )
24031 <returnvalue>boolean</returnvalue>
24032 </para>
24033 <para>
24034 Does user have privilege for tablespace?
24035 The only allowable privilege type is <literal>CREATE</literal>.
24036 </para></entry>
24037 </row>
24039 <row>
24040 <entry role="func_table_entry"><para role="func_signature">
24041 <indexterm>
24042 <primary>has_type_privilege</primary>
24043 </indexterm>
24044 <function>has_type_privilege</function> (
24045 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
24046 <parameter>type</parameter> <type>text</type> or <type>oid</type>,
24047 <parameter>privilege</parameter> <type>text</type> )
24048 <returnvalue>boolean</returnvalue>
24049 </para>
24050 <para>
24051 Does user have privilege for data type?
24052 The only allowable privilege type is <literal>USAGE</literal>.
24053 When specifying a type by name rather than by OID, the allowed input
24054 is the same as for the <type>regtype</type> data type (see
24055 <xref linkend="datatype-oid"/>).
24056 </para></entry>
24057 </row>
24059 <row>
24060 <entry role="func_table_entry"><para role="func_signature">
24061 <indexterm>
24062 <primary>pg_has_role</primary>
24063 </indexterm>
24064 <function>pg_has_role</function> (
24065 <optional> <parameter>user</parameter> <type>name</type> or <type>oid</type>, </optional>
24066 <parameter>role</parameter> <type>text</type> or <type>oid</type>,
24067 <parameter>privilege</parameter> <type>text</type> )
24068 <returnvalue>boolean</returnvalue>
24069 </para>
24070 <para>
24071 Does user have privilege for role?
24072 Allowable privilege types are
24073 <literal>MEMBER</literal> and <literal>USAGE</literal>.
24074 <literal>MEMBER</literal> denotes direct or indirect membership in
24075 the role (that is, the right to do <command>SET ROLE</command>), while
24076 <literal>USAGE</literal> denotes whether the privileges of the role
24077 are immediately available without doing <command>SET ROLE</command>.
24078 This function does not allow the special case of
24079 setting <parameter>user</parameter> to <literal>public</literal>,
24080 because the PUBLIC pseudo-role can never be a member of real roles.
24081 </para></entry>
24082 </row>
24084 <row>
24085 <entry role="func_table_entry"><para role="func_signature">
24086 <indexterm>
24087 <primary>row_security_active</primary>
24088 </indexterm>
24089 <function>row_security_active</function> (
24090 <parameter>table</parameter> <type>text</type> or <type>oid</type> )
24091 <returnvalue>boolean</returnvalue>
24092 </para>
24093 <para>
24094 Is row-level security active for the specified table in the context of
24095 the current user and current environment?
24096 </para></entry>
24097 </row>
24098 </tbody>
24099 </tgroup>
24100 </table>
24102 <para>
24103 <xref linkend="functions-aclitem-op-table"/> shows the operators
24104 available for the <type>aclitem</type> type, which is the catalog
24105 representation of access privileges. See <xref linkend="ddl-priv"/>
24106 for information about how to read access privilege values.
24107 </para>
24109 <table id="functions-aclitem-op-table">
24110 <title><type>aclitem</type> Operators</title>
24111 <tgroup cols="1">
24112 <thead>
24113 <row>
24114 <entry role="func_table_entry"><para role="func_signature">
24115 Operator
24116 </para>
24117 <para>
24118 Description
24119 </para>
24120 <para>
24121 Example(s)
24122 </para></entry>
24123 </row>
24124 </thead>
24126 <tbody>
24127 <row>
24128 <entry role="func_table_entry"><para role="func_signature">
24129 <indexterm>
24130 <primary>aclitemeq</primary>
24131 </indexterm>
24132 <type>aclitem</type> <literal>=</literal> <type>aclitem</type>
24133 <returnvalue>boolean</returnvalue>
24134 </para>
24135 <para>
24136 Are <type>aclitem</type>s equal? (Notice that
24137 type <type>aclitem</type> lacks the usual set of comparison
24138 operators; it has only equality. In turn, <type>aclitem</type>
24139 arrays can only be compared for equality.)
24140 </para>
24141 <para>
24142 <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem</literal>
24143 <returnvalue>f</returnvalue>
24144 </para></entry>
24145 </row>
24147 <row>
24148 <entry role="func_table_entry"><para role="func_signature">
24149 <indexterm>
24150 <primary>aclcontains</primary>
24151 </indexterm>
24152 <type>aclitem[]</type> <literal>@&gt;</literal> <type>aclitem</type>
24153 <returnvalue>boolean</returnvalue>
24154 </para>
24155 <para>
24156 Does array contain the specified privileges? (This is true if there
24157 is an array entry that matches the <type>aclitem</type>'s grantee and
24158 grantor, and has at least the specified set of privileges.)
24159 </para>
24160 <para>
24161 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @&gt; 'calvin=r*/hobbes'::aclitem</literal>
24162 <returnvalue>t</returnvalue>
24163 </para></entry>
24164 </row>
24166 <row>
24167 <entry role="func_table_entry"><para role="func_signature">
24168 <type>aclitem[]</type> <literal>~</literal> <type>aclitem</type>
24169 <returnvalue>boolean</returnvalue>
24170 </para>
24171 <para>
24172 This is a deprecated alias for <literal>@&gt;</literal>.
24173 </para>
24174 <para>
24175 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem</literal>
24176 <returnvalue>t</returnvalue>
24177 </para></entry>
24178 </row>
24179 </tbody>
24180 </tgroup>
24181 </table>
24183 <para>
24184 <xref linkend="functions-aclitem-fn-table"/> shows some additional
24185 functions to manage the <type>aclitem</type> type.
24186 </para>
24188 <table id="functions-aclitem-fn-table">
24189 <title><type>aclitem</type> Functions</title>
24190 <tgroup cols="1">
24191 <thead>
24192 <row>
24193 <entry role="func_table_entry"><para role="func_signature">
24194 Function
24195 </para>
24196 <para>
24197 Description
24198 </para></entry>
24199 </row>
24200 </thead>
24202 <tbody>
24203 <row>
24204 <entry role="func_table_entry"><para role="func_signature">
24205 <indexterm>
24206 <primary>acldefault</primary>
24207 </indexterm>
24208 <function>acldefault</function> (
24209 <parameter>type</parameter> <type>"char"</type>,
24210 <parameter>ownerId</parameter> <type>oid</type> )
24211 <returnvalue>aclitem[]</returnvalue>
24212 </para>
24213 <para>
24214 Constructs an <type>aclitem</type> array holding the default access
24215 privileges for an object of type <parameter>type</parameter> belonging
24216 to the role with OID <parameter>ownerId</parameter>. This represents
24217 the access privileges that will be assumed when an object's ACL entry
24218 is null. (The default access privileges are described in
24219 <xref linkend="ddl-priv"/>.)
24220 The <parameter>type</parameter> parameter must be one of
24221 'c' for <literal>COLUMN</literal>,
24222 'r' for <literal>TABLE</literal> and table-like objects,
24223 's' for <literal>SEQUENCE</literal>,
24224 'd' for <literal>DATABASE</literal>,
24225 'f' for <literal>FUNCTION</literal> or <literal>PROCEDURE</literal>,
24226 'l' for <literal>LANGUAGE</literal>,
24227 'L' for <literal>LARGE OBJECT</literal>,
24228 'n' for <literal>SCHEMA</literal>,
24229 'p' for <literal>PARAMETER</literal>,
24230 't' for <literal>TABLESPACE</literal>,
24231 'F' for <literal>FOREIGN DATA WRAPPER</literal>,
24232 'S' for <literal>FOREIGN SERVER</literal>,
24234 'T' for <literal>TYPE</literal> or <literal>DOMAIN</literal>.
24235 </para></entry>
24236 </row>
24238 <row>
24239 <entry role="func_table_entry"><para role="func_signature">
24240 <indexterm>
24241 <primary>aclexplode</primary>
24242 </indexterm>
24243 <function>aclexplode</function> ( <type>aclitem[]</type> )
24244 <returnvalue>setof record</returnvalue>
24245 ( <parameter>grantor</parameter> <type>oid</type>,
24246 <parameter>grantee</parameter> <type>oid</type>,
24247 <parameter>privilege_type</parameter> <type>text</type>,
24248 <parameter>is_grantable</parameter> <type>boolean</type> )
24249 </para>
24250 <para>
24251 Returns the <type>aclitem</type> array as a set of rows.
24252 If the grantee is the pseudo-role PUBLIC, it is represented by zero in
24253 the <parameter>grantee</parameter> column. Each granted privilege is
24254 represented as <literal>SELECT</literal>, <literal>INSERT</literal>,
24255 etc (see <xref linkend="privilege-abbrevs-table"/> for a full list).
24256 Note that each privilege is broken out as a separate row, so
24257 only one keyword appears in the <parameter>privilege_type</parameter>
24258 column.
24259 </para></entry>
24260 </row>
24262 <row>
24263 <entry role="func_table_entry"><para role="func_signature">
24264 <indexterm>
24265 <primary>makeaclitem</primary>
24266 </indexterm>
24267 <function>makeaclitem</function> (
24268 <parameter>grantee</parameter> <type>oid</type>,
24269 <parameter>grantor</parameter> <type>oid</type>,
24270 <parameter>privileges</parameter> <type>text</type>,
24271 <parameter>is_grantable</parameter> <type>boolean</type> )
24272 <returnvalue>aclitem</returnvalue>
24273 </para>
24274 <para>
24275 Constructs an <type>aclitem</type> with the given properties.
24276 <parameter>privileges</parameter> is a comma-separated list of
24277 privilege names such as <literal>SELECT</literal>,
24278 <literal>INSERT</literal>, etc, all of which are set in the
24279 result. (Case of the privilege string is not significant, and
24280 extra whitespace is allowed between but not within privilege
24281 names.)
24282 </para></entry>
24283 </row>
24284 </tbody>
24285 </tgroup>
24286 </table>
24288 <para>
24289 <xref linkend="functions-info-schema-table"/> shows functions that
24290 determine whether a certain object is <firstterm>visible</firstterm> in the
24291 current schema search path.
24292 For example, a table is said to be visible if its
24293 containing schema is in the search path and no table of the same
24294 name appears earlier in the search path. This is equivalent to the
24295 statement that the table can be referenced by name without explicit
24296 schema qualification. Thus, to list the names of all visible tables:
24297 <programlisting>
24298 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
24299 </programlisting>
24300 For functions and operators, an object in the search path is said to be
24301 visible if there is no object of the same name <emphasis>and argument data
24302 type(s)</emphasis> earlier in the path. For operator classes and families,
24303 both the name and the associated index access method are considered.
24304 </para>
24306 <indexterm>
24307 <primary>search path</primary>
24308 <secondary>object visibility</secondary>
24309 </indexterm>
24311 <table id="functions-info-schema-table">
24312 <title>Schema Visibility Inquiry Functions</title>
24313 <tgroup cols="1">
24314 <thead>
24315 <row>
24316 <entry role="func_table_entry"><para role="func_signature">
24317 Function
24318 </para>
24319 <para>
24320 Description
24321 </para></entry>
24322 </row>
24323 </thead>
24325 <tbody>
24326 <row>
24327 <entry role="func_table_entry"><para role="func_signature">
24328 <indexterm>
24329 <primary>pg_collation_is_visible</primary>
24330 </indexterm>
24331 <function>pg_collation_is_visible</function> ( <parameter>collation</parameter> <type>oid</type> )
24332 <returnvalue>boolean</returnvalue>
24333 </para>
24334 <para>
24335 Is collation visible in search path?
24336 </para></entry>
24337 </row>
24339 <row>
24340 <entry role="func_table_entry"><para role="func_signature">
24341 <indexterm>
24342 <primary>pg_conversion_is_visible</primary>
24343 </indexterm>
24344 <function>pg_conversion_is_visible</function> ( <parameter>conversion</parameter> <type>oid</type> )
24345 <returnvalue>boolean</returnvalue>
24346 </para>
24347 <para>
24348 Is conversion visible in search path?
24349 </para></entry>
24350 </row>
24352 <row>
24353 <entry role="func_table_entry"><para role="func_signature">
24354 <indexterm>
24355 <primary>pg_function_is_visible</primary>
24356 </indexterm>
24357 <function>pg_function_is_visible</function> ( <parameter>function</parameter> <type>oid</type> )
24358 <returnvalue>boolean</returnvalue>
24359 </para>
24360 <para>
24361 Is function visible in search path?
24362 (This also works for procedures and aggregates.)
24363 </para></entry>
24364 </row>
24366 <row>
24367 <entry role="func_table_entry"><para role="func_signature">
24368 <indexterm>
24369 <primary>pg_opclass_is_visible</primary>
24370 </indexterm>
24371 <function>pg_opclass_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
24372 <returnvalue>boolean</returnvalue>
24373 </para>
24374 <para>
24375 Is operator class visible in search path?
24376 </para></entry>
24377 </row>
24379 <row>
24380 <entry role="func_table_entry"><para role="func_signature">
24381 <indexterm>
24382 <primary>pg_operator_is_visible</primary>
24383 </indexterm>
24384 <function>pg_operator_is_visible</function> ( <parameter>operator</parameter> <type>oid</type> )
24385 <returnvalue>boolean</returnvalue>
24386 </para>
24387 <para>
24388 Is operator visible in search path?
24389 </para></entry>
24390 </row>
24392 <row>
24393 <entry role="func_table_entry"><para role="func_signature">
24394 <indexterm>
24395 <primary>pg_opfamily_is_visible</primary>
24396 </indexterm>
24397 <function>pg_opfamily_is_visible</function> ( <parameter>opclass</parameter> <type>oid</type> )
24398 <returnvalue>boolean</returnvalue>
24399 </para>
24400 <para>
24401 Is operator family visible in search path?
24402 </para></entry>
24403 </row>
24405 <row>
24406 <entry role="func_table_entry"><para role="func_signature">
24407 <indexterm>
24408 <primary>pg_statistics_obj_is_visible</primary>
24409 </indexterm>
24410 <function>pg_statistics_obj_is_visible</function> ( <parameter>stat</parameter> <type>oid</type> )
24411 <returnvalue>boolean</returnvalue>
24412 </para>
24413 <para>
24414 Is statistics object visible in search path?
24415 </para></entry>
24416 </row>
24418 <row>
24419 <entry role="func_table_entry"><para role="func_signature">
24420 <indexterm>
24421 <primary>pg_table_is_visible</primary>
24422 </indexterm>
24423 <function>pg_table_is_visible</function> ( <parameter>table</parameter> <type>oid</type> )
24424 <returnvalue>boolean</returnvalue>
24425 </para>
24426 <para>
24427 Is table visible in search path?
24428 (This works for all types of relations, including views, materialized
24429 views, indexes, sequences and foreign tables.)
24430 </para></entry>
24431 </row>
24433 <row>
24434 <entry role="func_table_entry"><para role="func_signature">
24435 <indexterm>
24436 <primary>pg_ts_config_is_visible</primary>
24437 </indexterm>
24438 <function>pg_ts_config_is_visible</function> ( <parameter>config</parameter> <type>oid</type> )
24439 <returnvalue>boolean</returnvalue>
24440 </para>
24441 <para>
24442 Is text search configuration visible in search path?
24443 </para></entry>
24444 </row>
24446 <row>
24447 <entry role="func_table_entry"><para role="func_signature">
24448 <indexterm>
24449 <primary>pg_ts_dict_is_visible</primary>
24450 </indexterm>
24451 <function>pg_ts_dict_is_visible</function> ( <parameter>dict</parameter> <type>oid</type> )
24452 <returnvalue>boolean</returnvalue>
24453 </para>
24454 <para>
24455 Is text search dictionary visible in search path?
24456 </para></entry>
24457 </row>
24459 <row>
24460 <entry role="func_table_entry"><para role="func_signature">
24461 <indexterm>
24462 <primary>pg_ts_parser_is_visible</primary>
24463 </indexterm>
24464 <function>pg_ts_parser_is_visible</function> ( <parameter>parser</parameter> <type>oid</type> )
24465 <returnvalue>boolean</returnvalue>
24466 </para>
24467 <para>
24468 Is text search parser visible in search path?
24469 </para></entry>
24470 </row>
24472 <row>
24473 <entry role="func_table_entry"><para role="func_signature">
24474 <indexterm>
24475 <primary>pg_ts_template_is_visible</primary>
24476 </indexterm>
24477 <function>pg_ts_template_is_visible</function> ( <parameter>template</parameter> <type>oid</type> )
24478 <returnvalue>boolean</returnvalue>
24479 </para>
24480 <para>
24481 Is text search template visible in search path?
24482 </para></entry>
24483 </row>
24485 <row>
24486 <entry role="func_table_entry"><para role="func_signature">
24487 <indexterm>
24488 <primary>pg_type_is_visible</primary>
24489 </indexterm>
24490 <function>pg_type_is_visible</function> ( <parameter>type</parameter> <type>oid</type> )
24491 <returnvalue>boolean</returnvalue>
24492 </para>
24493 <para>
24494 Is type (or domain) visible in search path?
24495 </para></entry>
24496 </row>
24497 </tbody>
24498 </tgroup>
24499 </table>
24501 <para>
24502 All these functions require object OIDs to identify the object to be
24503 checked. If you want to test an object by name, it is convenient to use
24504 the OID alias types (<type>regclass</type>, <type>regtype</type>,
24505 <type>regprocedure</type>, <type>regoperator</type>, <type>regconfig</type>,
24506 or <type>regdictionary</type>),
24507 for example:
24508 <programlisting>
24509 SELECT pg_type_is_visible('myschema.widget'::regtype);
24510 </programlisting>
24511 Note that it would not make much sense to test a non-schema-qualified
24512 type name in this way &mdash; if the name can be recognized at all, it must be visible.
24513 </para>
24515 <para>
24516 <xref linkend="functions-info-catalog-table"/> lists functions that
24517 extract information from the system catalogs.
24518 </para>
24520 <table id="functions-info-catalog-table">
24521 <title>System Catalog Information Functions</title>
24522 <tgroup cols="1">
24523 <thead>
24524 <row>
24525 <entry role="func_table_entry"><para role="func_signature">
24526 Function
24527 </para>
24528 <para>
24529 Description
24530 </para></entry>
24531 </row>
24532 </thead>
24534 <tbody>
24535 <row>
24536 <entry role="func_table_entry"><para role="func_signature">
24537 <indexterm>
24538 <primary>format_type</primary>
24539 </indexterm>
24540 <function>format_type</function> ( <parameter>type</parameter> <type>oid</type>, <parameter>typemod</parameter> <type>integer</type> )
24541 <returnvalue>text</returnvalue>
24542 </para>
24543 <para>
24544 Returns the SQL name for a data type that is identified by its type
24545 OID and possibly a type modifier. Pass NULL for the type modifier if
24546 no specific modifier is known.
24547 </para></entry>
24548 </row>
24550 <row>
24551 <entry id="pg-char-to-encoding" role="func_table_entry"><para role="func_signature">
24552 <indexterm>
24553 <primary>pg_char_to_encoding</primary>
24554 </indexterm>
24555 <function>pg_char_to_encoding</function> ( <parameter>encoding</parameter> <type>name</type> )
24556 <returnvalue>integer</returnvalue>
24557 </para>
24558 <para>
24559 Converts the supplied encoding name into an integer representing the
24560 internal identifier used in some system catalog tables.
24561 Returns <literal>-1</literal> if an unknown encoding name is provided.
24562 </para></entry>
24563 </row>
24565 <row>
24566 <entry id="pg-encoding-to-char" role="func_table_entry"><para role="func_signature">
24567 <indexterm>
24568 <primary>pg_encoding_to_char</primary>
24569 </indexterm>
24570 <function>pg_encoding_to_char</function> ( <parameter>encoding</parameter> <type>integer</type> )
24571 <returnvalue>name</returnvalue>
24572 </para>
24573 <para>
24574 Converts the integer used as the internal identifier of an encoding in some
24575 system catalog tables into a human-readable string.
24576 Returns an empty string if an invalid encoding number is provided.
24577 </para></entry>
24578 </row>
24580 <row>
24581 <entry role="func_table_entry"><para role="func_signature">
24582 <indexterm>
24583 <primary>pg_get_catalog_foreign_keys</primary>
24584 </indexterm>
24585 <function>pg_get_catalog_foreign_keys</function> ()
24586 <returnvalue>setof record</returnvalue>
24587 ( <parameter>fktable</parameter> <type>regclass</type>,
24588 <parameter>fkcols</parameter> <type>text[]</type>,
24589 <parameter>pktable</parameter> <type>regclass</type>,
24590 <parameter>pkcols</parameter> <type>text[]</type>,
24591 <parameter>is_array</parameter> <type>boolean</type>,
24592 <parameter>is_opt</parameter> <type>boolean</type> )
24593 </para>
24594 <para>
24595 Returns a set of records describing the foreign key relationships
24596 that exist within the <productname>PostgreSQL</productname> system
24597 catalogs.
24598 The <parameter>fktable</parameter> column contains the name of the
24599 referencing catalog, and the <parameter>fkcols</parameter> column
24600 contains the name(s) of the referencing column(s). Similarly,
24601 the <parameter>pktable</parameter> column contains the name of the
24602 referenced catalog, and the <parameter>pkcols</parameter> column
24603 contains the name(s) of the referenced column(s).
24604 If <parameter>is_array</parameter> is true, the last referencing
24605 column is an array, each of whose elements should match some entry
24606 in the referenced catalog.
24607 If <parameter>is_opt</parameter> is true, the referencing column(s)
24608 are allowed to contain zeroes instead of a valid reference.
24609 </para></entry>
24610 </row>
24612 <row>
24613 <entry role="func_table_entry"><para role="func_signature">
24614 <indexterm>
24615 <primary>pg_get_constraintdef</primary>
24616 </indexterm>
24617 <function>pg_get_constraintdef</function> ( <parameter>constraint</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24618 <returnvalue>text</returnvalue>
24619 </para>
24620 <para>
24621 Reconstructs the creating command for a constraint.
24622 (This is a decompiled reconstruction, not the original text
24623 of the command.)
24624 </para></entry>
24625 </row>
24627 <row>
24628 <entry role="func_table_entry"><para role="func_signature">
24629 <indexterm>
24630 <primary>pg_get_expr</primary>
24631 </indexterm>
24632 <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> )
24633 <returnvalue>text</returnvalue>
24634 </para>
24635 <para>
24636 Decompiles the internal form of an expression stored in the system
24637 catalogs, such as the default value for a column. If the expression
24638 might contain Vars, specify the OID of the relation they refer to as
24639 the second parameter; if no Vars are expected, passing zero is
24640 sufficient.
24641 </para></entry>
24642 </row>
24644 <row>
24645 <entry role="func_table_entry"><para role="func_signature">
24646 <indexterm>
24647 <primary>pg_get_functiondef</primary>
24648 </indexterm>
24649 <function>pg_get_functiondef</function> ( <parameter>func</parameter> <type>oid</type> )
24650 <returnvalue>text</returnvalue>
24651 </para>
24652 <para>
24653 Reconstructs the creating command for a function or procedure.
24654 (This is a decompiled reconstruction, not the original text
24655 of the command.)
24656 The result is a complete <command>CREATE OR REPLACE FUNCTION</command>
24657 or <command>CREATE OR REPLACE PROCEDURE</command> statement.
24658 </para></entry>
24659 </row>
24661 <row>
24662 <entry role="func_table_entry"><para role="func_signature">
24663 <indexterm>
24664 <primary>pg_get_function_arguments</primary>
24665 </indexterm>
24666 <function>pg_get_function_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
24667 <returnvalue>text</returnvalue>
24668 </para>
24669 <para>
24670 Reconstructs the argument list of a function or procedure, in the form
24671 it would need to appear in within <command>CREATE FUNCTION</command>
24672 (including default values).
24673 </para></entry>
24674 </row>
24676 <row>
24677 <entry role="func_table_entry"><para role="func_signature">
24678 <indexterm>
24679 <primary>pg_get_function_identity_arguments</primary>
24680 </indexterm>
24681 <function>pg_get_function_identity_arguments</function> ( <parameter>func</parameter> <type>oid</type> )
24682 <returnvalue>text</returnvalue>
24683 </para>
24684 <para>
24685 Reconstructs the argument list necessary to identify a function or
24686 procedure, in the form it would need to appear in within commands such
24687 as <command>ALTER FUNCTION</command>. This form omits default values.
24688 </para></entry>
24689 </row>
24691 <row>
24692 <entry role="func_table_entry"><para role="func_signature">
24693 <indexterm>
24694 <primary>pg_get_function_result</primary>
24695 </indexterm>
24696 <function>pg_get_function_result</function> ( <parameter>func</parameter> <type>oid</type> )
24697 <returnvalue>text</returnvalue>
24698 </para>
24699 <para>
24700 Reconstructs the <literal>RETURNS</literal> clause of a function, in
24701 the form it would need to appear in within <command>CREATE
24702 FUNCTION</command>. Returns <literal>NULL</literal> for a procedure.
24703 </para></entry>
24704 </row>
24706 <row>
24707 <entry role="func_table_entry"><para role="func_signature">
24708 <indexterm>
24709 <primary>pg_get_indexdef</primary>
24710 </indexterm>
24711 <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> )
24712 <returnvalue>text</returnvalue>
24713 </para>
24714 <para>
24715 Reconstructs the creating command for an index.
24716 (This is a decompiled reconstruction, not the original text
24717 of the command.) If <parameter>column</parameter> is supplied and is
24718 not zero, only the definition of that column is reconstructed.
24719 </para></entry>
24720 </row>
24722 <row>
24723 <entry role="func_table_entry"><para role="func_signature">
24724 <indexterm>
24725 <primary>pg_get_keywords</primary>
24726 </indexterm>
24727 <function>pg_get_keywords</function> ()
24728 <returnvalue>setof record</returnvalue>
24729 ( <parameter>word</parameter> <type>text</type>,
24730 <parameter>catcode</parameter> <type>"char"</type>,
24731 <parameter>barelabel</parameter> <type>boolean</type>,
24732 <parameter>catdesc</parameter> <type>text</type>,
24733 <parameter>baredesc</parameter> <type>text</type> )
24734 </para>
24735 <para>
24736 Returns a set of records describing the SQL keywords recognized by the
24737 server. The <parameter>word</parameter> column contains the
24738 keyword. The <parameter>catcode</parameter> column contains a
24739 category code: <literal>U</literal> for an unreserved
24740 keyword, <literal>C</literal> for a keyword that can be a column
24741 name, <literal>T</literal> for a keyword that can be a type or
24742 function name, or <literal>R</literal> for a fully reserved keyword.
24743 The <parameter>barelabel</parameter> column
24744 contains <literal>true</literal> if the keyword can be used as
24745 a <quote>bare</quote> column label in <command>SELECT</command> lists,
24746 or <literal>false</literal> if it can only be used
24747 after <literal>AS</literal>.
24748 The <parameter>catdesc</parameter> column contains a
24749 possibly-localized string describing the keyword's category.
24750 The <parameter>baredesc</parameter> column contains a
24751 possibly-localized string describing the keyword's column label status.
24752 </para></entry>
24753 </row>
24755 <row>
24756 <entry role="func_table_entry"><para role="func_signature">
24757 <indexterm>
24758 <primary>pg_get_ruledef</primary>
24759 </indexterm>
24760 <function>pg_get_ruledef</function> ( <parameter>rule</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24761 <returnvalue>text</returnvalue>
24762 </para>
24763 <para>
24764 Reconstructs the creating command for a rule.
24765 (This is a decompiled reconstruction, not the original text
24766 of the command.)
24767 </para></entry>
24768 </row>
24770 <row>
24771 <entry role="func_table_entry"><para role="func_signature">
24772 <indexterm>
24773 <primary>pg_get_serial_sequence</primary>
24774 </indexterm>
24775 <function>pg_get_serial_sequence</function> ( <parameter>table</parameter> <type>text</type>, <parameter>column</parameter> <type>text</type> )
24776 <returnvalue>text</returnvalue>
24777 </para>
24778 <para>
24779 Returns the name of the sequence associated with a column,
24780 or NULL if no sequence is associated with the column.
24781 If the column is an identity column, the associated sequence is the
24782 sequence internally created for that column.
24783 For columns created using one of the serial types
24784 (<type>serial</type>, <type>smallserial</type>, <type>bigserial</type>),
24785 it is the sequence created for that serial column definition.
24786 In the latter case, the association can be modified or removed
24787 with <command>ALTER SEQUENCE OWNED BY</command>.
24788 (This function probably should have been
24789 called <function>pg_get_owned_sequence</function>; its current name
24790 reflects the fact that it has historically been used with serial-type
24791 columns.) The first parameter is a table name with optional
24792 schema, and the second parameter is a column name. Because the first
24793 parameter potentially contains both schema and table names, it is
24794 parsed per usual SQL rules, meaning it is lower-cased by default.
24795 The second parameter, being just a column name, is treated literally
24796 and so has its case preserved. The result is suitably formatted
24797 for passing to the sequence functions (see
24798 <xref linkend="functions-sequence"/>).
24799 </para>
24800 <para>
24801 A typical use is in reading the current value of the sequence for an
24802 identity or serial column, for example:
24803 <programlisting>
24804 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
24805 </programlisting>
24806 </para></entry>
24807 </row>
24809 <row>
24810 <entry role="func_table_entry"><para role="func_signature">
24811 <indexterm>
24812 <primary>pg_get_statisticsobjdef</primary>
24813 </indexterm>
24814 <function>pg_get_statisticsobjdef</function> ( <parameter>statobj</parameter> <type>oid</type> )
24815 <returnvalue>text</returnvalue>
24816 </para>
24817 <para>
24818 Reconstructs the creating command for an extended statistics object.
24819 (This is a decompiled reconstruction, not the original text
24820 of the command.)
24821 </para></entry>
24822 </row>
24824 <row>
24825 <entry role="func_table_entry"><para role="func_signature">
24826 <indexterm>
24827 <primary>pg_get_triggerdef</primary>
24828 </indexterm>
24829 <function>pg_get_triggerdef</function> ( <parameter>trigger</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24830 <returnvalue>text</returnvalue>
24831 </para>
24832 <para>
24833 Reconstructs the creating command for a trigger.
24834 (This is a decompiled reconstruction, not the original text
24835 of the command.)
24836 </para></entry>
24837 </row>
24839 <row>
24840 <entry role="func_table_entry"><para role="func_signature">
24841 <indexterm>
24842 <primary>pg_get_userbyid</primary>
24843 </indexterm>
24844 <function>pg_get_userbyid</function> ( <parameter>role</parameter> <type>oid</type> )
24845 <returnvalue>name</returnvalue>
24846 </para>
24847 <para>
24848 Returns a role's name given its OID.
24849 </para></entry>
24850 </row>
24852 <row>
24853 <entry role="func_table_entry"><para role="func_signature">
24854 <indexterm>
24855 <primary>pg_get_viewdef</primary>
24856 </indexterm>
24857 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24858 <returnvalue>text</returnvalue>
24859 </para>
24860 <para>
24861 Reconstructs the underlying <command>SELECT</command> command for a
24862 view or materialized view. (This is a decompiled reconstruction, not
24863 the original text of the command.)
24864 </para></entry>
24865 </row>
24867 <row>
24868 <entry role="func_table_entry"><para role="func_signature">
24869 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>oid</type>, <parameter>wrap_column</parameter> <type>integer</type> )
24870 <returnvalue>text</returnvalue>
24871 </para>
24872 <para>
24873 Reconstructs the underlying <command>SELECT</command> command for a
24874 view or materialized view. (This is a decompiled reconstruction, not
24875 the original text of the command.) In this form of the function,
24876 pretty-printing is always enabled, and long lines are wrapped to try
24877 to keep them shorter than the specified number of columns.
24878 </para></entry>
24879 </row>
24881 <row>
24882 <entry role="func_table_entry"><para role="func_signature">
24883 <function>pg_get_viewdef</function> ( <parameter>view</parameter> <type>text</type> <optional>, <parameter>pretty</parameter> <type>boolean</type> </optional> )
24884 <returnvalue>text</returnvalue>
24885 </para>
24886 <para>
24887 Reconstructs the underlying <command>SELECT</command> command for a
24888 view or materialized view, working from a textual name for the view
24889 rather than its OID. (This is deprecated; use the OID variant
24890 instead.)
24891 </para></entry>
24892 </row>
24894 <row>
24895 <entry role="func_table_entry"><para role="func_signature">
24896 <indexterm>
24897 <primary>pg_index_column_has_property</primary>
24898 </indexterm>
24899 <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> )
24900 <returnvalue>boolean</returnvalue>
24901 </para>
24902 <para>
24903 Tests whether an index column has the named property.
24904 Common index column properties are listed in
24905 <xref linkend="functions-info-index-column-props"/>.
24906 (Note that extension access methods can define additional property
24907 names for their indexes.)
24908 <literal>NULL</literal> is returned if the property name is not known
24909 or does not apply to the particular object, or if the OID or column
24910 number does not identify a valid object.
24911 </para></entry>
24912 </row>
24914 <row>
24915 <entry role="func_table_entry"><para role="func_signature">
24916 <indexterm>
24917 <primary>pg_index_has_property</primary>
24918 </indexterm>
24919 <function>pg_index_has_property</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>property</parameter> <type>text</type> )
24920 <returnvalue>boolean</returnvalue>
24921 </para>
24922 <para>
24923 Tests whether an index has the named property.
24924 Common index properties are listed in
24925 <xref linkend="functions-info-index-props"/>.
24926 (Note that extension access methods can define additional property
24927 names for their indexes.)
24928 <literal>NULL</literal> is returned if the property name is not known
24929 or does not apply to the particular object, or if the OID does not
24930 identify a valid object.
24931 </para></entry>
24932 </row>
24934 <row>
24935 <entry role="func_table_entry"><para role="func_signature">
24936 <indexterm>
24937 <primary>pg_indexam_has_property</primary>
24938 </indexterm>
24939 <function>pg_indexam_has_property</function> ( <parameter>am</parameter> <type>oid</type>, <parameter>property</parameter> <type>text</type> )
24940 <returnvalue>boolean</returnvalue>
24941 </para>
24942 <para>
24943 Tests whether an index access method has the named property.
24944 Access method properties are listed in
24945 <xref linkend="functions-info-indexam-props"/>.
24946 <literal>NULL</literal> is returned if the property name is not known
24947 or does not apply to the particular object, or if the OID does not
24948 identify a valid object.
24949 </para></entry>
24950 </row>
24952 <row>
24953 <entry role="func_table_entry"><para role="func_signature">
24954 <indexterm>
24955 <primary>pg_options_to_table</primary>
24956 </indexterm>
24957 <function>pg_options_to_table</function> ( <parameter>options_array</parameter> <type>text[]</type> )
24958 <returnvalue>setof record</returnvalue>
24959 ( <parameter>option_name</parameter> <type>text</type>,
24960 <parameter>option_value</parameter> <type>text</type> )
24961 </para>
24962 <para>
24963 Returns the set of storage options represented by a value from
24964 <structname>pg_class</structname>.<structfield>reloptions</structfield> or
24965 <structname>pg_attribute</structname>.<structfield>attoptions</structfield>.
24966 </para></entry>
24967 </row>
24969 <row>
24970 <entry role="func_table_entry"><para role="func_signature">
24971 <indexterm>
24972 <primary>pg_settings_get_flags</primary>
24973 </indexterm>
24974 <function>pg_settings_get_flags</function> ( <parameter>guc</parameter> <type>text</type> )
24975 <returnvalue>text[]</returnvalue>
24976 </para>
24977 <para>
24978 Returns an array of the flags associated with the given GUC, or
24979 <literal>NULL</literal> if it does not exist. The result is
24980 an empty array if the GUC exists but there are no flags to show.
24981 Only the most useful flags listed in
24982 <xref linkend="functions-pg-settings-flags"/> are exposed.
24983 </para></entry>
24984 </row>
24986 <row>
24987 <entry role="func_table_entry"><para role="func_signature">
24988 <indexterm>
24989 <primary>pg_tablespace_databases</primary>
24990 </indexterm>
24991 <function>pg_tablespace_databases</function> ( <parameter>tablespace</parameter> <type>oid</type> )
24992 <returnvalue>setof oid</returnvalue>
24993 </para>
24994 <para>
24995 Returns the set of OIDs of databases that have objects stored in the
24996 specified tablespace. If this function returns any rows, the
24997 tablespace is not empty and cannot be dropped. To identify the specific
24998 objects populating the tablespace, you will need to connect to the
24999 database(s) identified by <function>pg_tablespace_databases</function>
25000 and query their <structname>pg_class</structname> catalogs.
25001 </para></entry>
25002 </row>
25004 <row>
25005 <entry role="func_table_entry"><para role="func_signature">
25006 <indexterm>
25007 <primary>pg_tablespace_location</primary>
25008 </indexterm>
25009 <function>pg_tablespace_location</function> ( <parameter>tablespace</parameter> <type>oid</type> )
25010 <returnvalue>text</returnvalue>
25011 </para>
25012 <para>
25013 Returns the file system path that this tablespace is located in.
25014 </para></entry>
25015 </row>
25017 <row>
25018 <entry role="func_table_entry"><para role="func_signature">
25019 <indexterm>
25020 <primary>pg_typeof</primary>
25021 </indexterm>
25022 <function>pg_typeof</function> ( <type>"any"</type> )
25023 <returnvalue>regtype</returnvalue>
25024 </para>
25025 <para>
25026 Returns the OID of the data type of the value that is passed to it.
25027 This can be helpful for troubleshooting or dynamically constructing
25028 SQL queries. The function is declared as
25029 returning <type>regtype</type>, which is an OID alias type (see
25030 <xref linkend="datatype-oid"/>); this means that it is the same as an
25031 OID for comparison purposes but displays as a type name.
25032 </para>
25033 <para>
25034 For example:
25035 <programlisting>
25036 SELECT pg_typeof(33);
25037 pg_typeof
25038 -----------
25039 integer
25041 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
25042 typlen
25043 --------
25045 </programlisting>
25046 </para></entry>
25047 </row>
25049 <row>
25050 <entry role="func_table_entry"><para role="func_signature">
25051 <indexterm>
25052 <primary>COLLATION FOR</primary>
25053 </indexterm>
25054 <function>COLLATION FOR</function> ( <type>"any"</type> )
25055 <returnvalue>text</returnvalue>
25056 </para>
25057 <para>
25058 Returns the name of the collation of the value that is passed to it.
25059 The value is quoted and schema-qualified if necessary. If no
25060 collation was derived for the argument expression,
25061 then <literal>NULL</literal> is returned. If the argument is not of a
25062 collatable data type, then an error is raised.
25063 </para>
25064 <para>
25065 For example:
25066 <programlisting>
25067 SELECT collation for (description) FROM pg_description LIMIT 1;
25068 pg_collation_for
25069 ------------------
25070 "default"
25072 SELECT collation for ('foo' COLLATE "de_DE");
25073 pg_collation_for
25074 ------------------
25075 "de_DE"
25076 </programlisting>
25077 </para></entry>
25078 </row>
25080 <row>
25081 <entry role="func_table_entry"><para role="func_signature">
25082 <indexterm>
25083 <primary>to_regclass</primary>
25084 </indexterm>
25085 <function>to_regclass</function> ( <type>text</type> )
25086 <returnvalue>regclass</returnvalue>
25087 </para>
25088 <para>
25089 Translates a textual relation name to its OID. A similar result is
25090 obtained by casting the string to type <type>regclass</type> (see
25091 <xref linkend="datatype-oid"/>); however, this function will return
25092 <literal>NULL</literal> rather than throwing an error if the name is
25093 not found. Also unlike the cast, this does not accept
25094 a numeric OID as input.
25095 </para></entry>
25096 </row>
25098 <row>
25099 <entry role="func_table_entry"><para role="func_signature">
25100 <indexterm>
25101 <primary>to_regcollation</primary>
25102 </indexterm>
25103 <function>to_regcollation</function> ( <type>text</type> )
25104 <returnvalue>regcollation</returnvalue>
25105 </para>
25106 <para>
25107 Translates a textual collation name to its OID. A similar result is
25108 obtained by casting the string to type <type>regcollation</type> (see
25109 <xref linkend="datatype-oid"/>); however, this function will return
25110 <literal>NULL</literal> rather than throwing an error if the name is
25111 not found. Also unlike the cast, this does not accept
25112 a numeric OID as input.
25113 </para></entry>
25114 </row>
25116 <row>
25117 <entry role="func_table_entry"><para role="func_signature">
25118 <indexterm>
25119 <primary>to_regnamespace</primary>
25120 </indexterm>
25121 <function>to_regnamespace</function> ( <type>text</type> )
25122 <returnvalue>regnamespace</returnvalue>
25123 </para>
25124 <para>
25125 Translates a textual schema name to its OID. A similar result is
25126 obtained by casting the string to type <type>regnamespace</type> (see
25127 <xref linkend="datatype-oid"/>); however, this function will return
25128 <literal>NULL</literal> rather than throwing an error if the name is
25129 not found. Also unlike the cast, this does not accept
25130 a numeric OID as input.
25131 </para></entry>
25132 </row>
25134 <row>
25135 <entry role="func_table_entry"><para role="func_signature">
25136 <indexterm>
25137 <primary>to_regoper</primary>
25138 </indexterm>
25139 <function>to_regoper</function> ( <type>text</type> )
25140 <returnvalue>regoper</returnvalue>
25141 </para>
25142 <para>
25143 Translates a textual operator name to its OID. A similar result is
25144 obtained by casting the string to type <type>regoper</type> (see
25145 <xref linkend="datatype-oid"/>); however, this function will return
25146 <literal>NULL</literal> rather than throwing an error if the name is
25147 not found or is ambiguous. Also unlike the cast, this does not accept
25148 a numeric OID as input.
25149 </para></entry>
25150 </row>
25152 <row>
25153 <entry role="func_table_entry"><para role="func_signature">
25154 <indexterm>
25155 <primary>to_regoperator</primary>
25156 </indexterm>
25157 <function>to_regoperator</function> ( <type>text</type> )
25158 <returnvalue>regoperator</returnvalue>
25159 </para>
25160 <para>
25161 Translates a textual operator name (with parameter types) to its OID. A similar result is
25162 obtained by casting the string to type <type>regoperator</type> (see
25163 <xref linkend="datatype-oid"/>); however, this function will return
25164 <literal>NULL</literal> rather than throwing an error if the name is
25165 not found. Also unlike the cast, this does not accept
25166 a numeric OID as input.
25167 </para></entry>
25168 </row>
25170 <row>
25171 <entry role="func_table_entry"><para role="func_signature">
25172 <indexterm>
25173 <primary>to_regproc</primary>
25174 </indexterm>
25175 <function>to_regproc</function> ( <type>text</type> )
25176 <returnvalue>regproc</returnvalue>
25177 </para>
25178 <para>
25179 Translates a textual function or procedure name to its OID. A similar result is
25180 obtained by casting the string to type <type>regproc</type> (see
25181 <xref linkend="datatype-oid"/>); however, this function will return
25182 <literal>NULL</literal> rather than throwing an error if the name is
25183 not found or is ambiguous. Also unlike the cast, this does not accept
25184 a numeric OID as input.
25185 </para></entry>
25186 </row>
25188 <row>
25189 <entry role="func_table_entry"><para role="func_signature">
25190 <indexterm>
25191 <primary>to_regprocedure</primary>
25192 </indexterm>
25193 <function>to_regprocedure</function> ( <type>text</type> )
25194 <returnvalue>regprocedure</returnvalue>
25195 </para>
25196 <para>
25197 Translates a textual function or procedure name (with argument types) to its OID. A similar result is
25198 obtained by casting the string to type <type>regprocedure</type> (see
25199 <xref linkend="datatype-oid"/>); however, this function will return
25200 <literal>NULL</literal> rather than throwing an error if the name is
25201 not found. Also unlike the cast, this does not accept
25202 a numeric OID as input.
25203 </para></entry>
25204 </row>
25206 <row>
25207 <entry role="func_table_entry"><para role="func_signature">
25208 <indexterm>
25209 <primary>to_regrole</primary>
25210 </indexterm>
25211 <function>to_regrole</function> ( <type>text</type> )
25212 <returnvalue>regrole</returnvalue>
25213 </para>
25214 <para>
25215 Translates a textual role name to its OID. A similar result is
25216 obtained by casting the string to type <type>regrole</type> (see
25217 <xref linkend="datatype-oid"/>); however, this function will return
25218 <literal>NULL</literal> rather than throwing an error if the name is
25219 not found. Also unlike the cast, this does not accept
25220 a numeric OID as input.
25221 </para></entry>
25222 </row>
25224 <row>
25225 <entry role="func_table_entry"><para role="func_signature">
25226 <indexterm>
25227 <primary>to_regtype</primary>
25228 </indexterm>
25229 <function>to_regtype</function> ( <type>text</type> )
25230 <returnvalue>regtype</returnvalue>
25231 </para>
25232 <para>
25233 Translates a textual type name to its OID. A similar result is
25234 obtained by casting the string to type <type>regtype</type> (see
25235 <xref linkend="datatype-oid"/>); however, this function will return
25236 <literal>NULL</literal> rather than throwing an error if the name is
25237 not found. Also unlike the cast, this does not accept
25238 a numeric OID as input.
25239 </para></entry>
25240 </row>
25241 </tbody>
25242 </tgroup>
25243 </table>
25245 <para>
25246 Most of the functions that reconstruct (decompile) database objects
25247 have an optional <parameter>pretty</parameter> flag, which
25248 if <literal>true</literal> causes the result to
25249 be <quote>pretty-printed</quote>. Pretty-printing suppresses unnecessary
25250 parentheses and adds whitespace for legibility.
25251 The pretty-printed format is more readable, but the default format
25252 is more likely to be interpreted the same way by future versions of
25253 <productname>PostgreSQL</productname>; so avoid using pretty-printed output
25254 for dump purposes. Passing <literal>false</literal> for
25255 the <parameter>pretty</parameter> parameter yields the same result as
25256 omitting the parameter.
25257 </para>
25259 <table id="functions-info-index-column-props">
25260 <title>Index Column Properties</title>
25261 <tgroup cols="2">
25262 <thead>
25263 <row><entry>Name</entry><entry>Description</entry></row>
25264 </thead>
25265 <tbody>
25266 <row>
25267 <entry><literal>asc</literal></entry>
25268 <entry>Does the column sort in ascending order on a forward scan?
25269 </entry>
25270 </row>
25271 <row>
25272 <entry><literal>desc</literal></entry>
25273 <entry>Does the column sort in descending order on a forward scan?
25274 </entry>
25275 </row>
25276 <row>
25277 <entry><literal>nulls_first</literal></entry>
25278 <entry>Does the column sort with nulls first on a forward scan?
25279 </entry>
25280 </row>
25281 <row>
25282 <entry><literal>nulls_last</literal></entry>
25283 <entry>Does the column sort with nulls last on a forward scan?
25284 </entry>
25285 </row>
25286 <row>
25287 <entry><literal>orderable</literal></entry>
25288 <entry>Does the column possess any defined sort ordering?
25289 </entry>
25290 </row>
25291 <row>
25292 <entry><literal>distance_orderable</literal></entry>
25293 <entry>Can the column be scanned in order by a <quote>distance</quote>
25294 operator, for example <literal>ORDER BY col &lt;-&gt; constant</literal> ?
25295 </entry>
25296 </row>
25297 <row>
25298 <entry><literal>returnable</literal></entry>
25299 <entry>Can the column value be returned by an index-only scan?
25300 </entry>
25301 </row>
25302 <row>
25303 <entry><literal>search_array</literal></entry>
25304 <entry>Does the column natively support <literal>col = ANY(array)</literal>
25305 searches?
25306 </entry>
25307 </row>
25308 <row>
25309 <entry><literal>search_nulls</literal></entry>
25310 <entry>Does the column support <literal>IS NULL</literal> and
25311 <literal>IS NOT NULL</literal> searches?
25312 </entry>
25313 </row>
25314 </tbody>
25315 </tgroup>
25316 </table>
25318 <table id="functions-info-index-props">
25319 <title>Index Properties</title>
25320 <tgroup cols="2">
25321 <thead>
25322 <row><entry>Name</entry><entry>Description</entry></row>
25323 </thead>
25324 <tbody>
25325 <row>
25326 <entry><literal>clusterable</literal></entry>
25327 <entry>Can the index be used in a <literal>CLUSTER</literal> command?
25328 </entry>
25329 </row>
25330 <row>
25331 <entry><literal>index_scan</literal></entry>
25332 <entry>Does the index support plain (non-bitmap) scans?
25333 </entry>
25334 </row>
25335 <row>
25336 <entry><literal>bitmap_scan</literal></entry>
25337 <entry>Does the index support bitmap scans?
25338 </entry>
25339 </row>
25340 <row>
25341 <entry><literal>backward_scan</literal></entry>
25342 <entry>Can the scan direction be changed in mid-scan (to
25343 support <literal>FETCH BACKWARD</literal> on a cursor without
25344 needing materialization)?
25345 </entry>
25346 </row>
25347 </tbody>
25348 </tgroup>
25349 </table>
25351 <table id="functions-info-indexam-props">
25352 <title>Index Access Method Properties</title>
25353 <tgroup cols="2">
25354 <thead>
25355 <row><entry>Name</entry><entry>Description</entry></row>
25356 </thead>
25357 <tbody>
25358 <row>
25359 <entry><literal>can_order</literal></entry>
25360 <entry>Does the access method support <literal>ASC</literal>,
25361 <literal>DESC</literal> and related keywords in
25362 <literal>CREATE INDEX</literal>?
25363 </entry>
25364 </row>
25365 <row>
25366 <entry><literal>can_unique</literal></entry>
25367 <entry>Does the access method support unique indexes?
25368 </entry>
25369 </row>
25370 <row>
25371 <entry><literal>can_multi_col</literal></entry>
25372 <entry>Does the access method support indexes with multiple columns?
25373 </entry>
25374 </row>
25375 <row>
25376 <entry><literal>can_exclude</literal></entry>
25377 <entry>Does the access method support exclusion constraints?
25378 </entry>
25379 </row>
25380 <row>
25381 <entry><literal>can_include</literal></entry>
25382 <entry>Does the access method support the <literal>INCLUDE</literal>
25383 clause of <literal>CREATE INDEX</literal>?
25384 </entry>
25385 </row>
25386 </tbody>
25387 </tgroup>
25388 </table>
25390 <table id="functions-pg-settings-flags">
25391 <title>GUC Flags</title>
25392 <tgroup cols="2">
25393 <thead>
25394 <row><entry>Flag</entry><entry>Description</entry></row>
25395 </thead>
25396 <tbody>
25397 <row>
25398 <entry><literal>EXPLAIN</literal></entry>
25399 <entry>Parameters with this flag are included in
25400 <command>EXPLAIN (SETTINGS)</command> commands.
25401 </entry>
25402 </row>
25403 <row>
25404 <entry><literal>NO_SHOW_ALL</literal></entry>
25405 <entry>Parameters with this flag are excluded from
25406 <command>SHOW ALL</command> commands.
25407 </entry>
25408 </row>
25409 <row>
25410 <entry><literal>NO_RESET_ALL</literal></entry>
25411 <entry>Parameters with this flag are excluded from
25412 <command>RESET ALL</command> commands.
25413 </entry>
25414 </row>
25415 <row>
25416 <entry><literal>NOT_IN_SAMPLE</literal></entry>
25417 <entry>Parameters with this flag are not included in
25418 <filename>postgresql.conf</filename> by default.
25419 </entry>
25420 </row>
25421 <row>
25422 <entry><literal>RUNTIME_COMPUTED</literal></entry>
25423 <entry>Parameters with this flag are runtime-computed ones.
25424 </entry>
25425 </row>
25426 </tbody>
25427 </tgroup>
25428 </table>
25430 <para>
25431 <xref linkend="functions-info-object-table"/> lists functions related to
25432 database object identification and addressing.
25433 </para>
25435 <table id="functions-info-object-table">
25436 <title>Object Information and Addressing Functions</title>
25437 <tgroup cols="1">
25438 <thead>
25439 <row>
25440 <entry role="func_table_entry"><para role="func_signature">
25441 Function
25442 </para>
25443 <para>
25444 Description
25445 </para></entry>
25446 </row>
25447 </thead>
25449 <tbody>
25450 <row>
25451 <entry role="func_table_entry"><para role="func_signature">
25452 <indexterm>
25453 <primary>pg_describe_object</primary>
25454 </indexterm>
25455 <function>pg_describe_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
25456 <returnvalue>text</returnvalue>
25457 </para>
25458 <para>
25459 Returns a textual description of a database object identified by
25460 catalog OID, object OID, and sub-object ID (such as a column number
25461 within a table; the sub-object ID is zero when referring to a whole
25462 object). This description is intended to be human-readable, and might
25463 be translated, depending on server configuration. This is especially
25464 useful to determine the identity of an object referenced in the
25465 <structname>pg_depend</structname> catalog. This function returns
25466 <literal>NULL</literal> values for undefined objects.
25467 </para></entry>
25468 </row>
25470 <row>
25471 <entry role="func_table_entry"><para role="func_signature">
25472 <indexterm>
25473 <primary>pg_identify_object</primary>
25474 </indexterm>
25475 <function>pg_identify_object</function> ( <parameter>classid</parameter> <type>oid</type>, <parameter>objid</parameter> <type>oid</type>, <parameter>objsubid</parameter> <type>integer</type> )
25476 <returnvalue>record</returnvalue>
25477 ( <parameter>type</parameter> <type>text</type>,
25478 <parameter>schema</parameter> <type>text</type>,
25479 <parameter>name</parameter> <type>text</type>,
25480 <parameter>identity</parameter> <type>text</type> )
25481 </para>
25482 <para>
25483 Returns a row containing enough information to uniquely identify the
25484 database object specified by catalog OID, object OID and sub-object
25486 This information is intended to be machine-readable, and is never
25487 translated.
25488 <parameter>type</parameter> identifies the type of database object;
25489 <parameter>schema</parameter> is the schema name that the object
25490 belongs in, or <literal>NULL</literal> for object types that do not
25491 belong to schemas;
25492 <parameter>name</parameter> is the name of the object, quoted if
25493 necessary, if the name (along with schema name, if pertinent) is
25494 sufficient to uniquely identify the object,
25495 otherwise <literal>NULL</literal>;
25496 <parameter>identity</parameter> is the complete object identity, with
25497 the precise format depending on object type, and each name within the
25498 format being schema-qualified and quoted as necessary. Undefined
25499 objects are identified with <literal>NULL</literal> values.
25500 </para></entry>
25501 </row>
25503 <row>
25504 <entry role="func_table_entry"><para role="func_signature">
25505 <indexterm>
25506 <primary>pg_identify_object_as_address</primary>
25507 </indexterm>
25508 <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> )
25509 <returnvalue>record</returnvalue>
25510 ( <parameter>type</parameter> <type>text</type>,
25511 <parameter>object_names</parameter> <type>text[]</type>,
25512 <parameter>object_args</parameter> <type>text[]</type> )
25513 </para>
25514 <para>
25515 Returns a row containing enough information to uniquely identify the
25516 database object specified by catalog OID, object OID and sub-object
25518 The returned information is independent of the current server, that
25519 is, it could be used to identify an identically named object in
25520 another server.
25521 <parameter>type</parameter> identifies the type of database object;
25522 <parameter>object_names</parameter> and
25523 <parameter>object_args</parameter>
25524 are text arrays that together form a reference to the object.
25525 These three values can be passed
25526 to <function>pg_get_object_address</function> to obtain the internal
25527 address of the object.
25528 </para></entry>
25529 </row>
25531 <row>
25532 <entry role="func_table_entry"><para role="func_signature">
25533 <indexterm>
25534 <primary>pg_get_object_address</primary>
25535 </indexterm>
25536 <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> )
25537 <returnvalue>record</returnvalue>
25538 ( <parameter>classid</parameter> <type>oid</type>,
25539 <parameter>objid</parameter> <type>oid</type>,
25540 <parameter>objsubid</parameter> <type>integer</type> )
25541 </para>
25542 <para>
25543 Returns a row containing enough information to uniquely identify the
25544 database object specified by a type code and object name and argument
25545 arrays.
25546 The returned values are the ones that would be used in system catalogs
25547 such as <structname>pg_depend</structname>; they can be passed to
25548 other system functions such as <function>pg_describe_object</function>
25549 or <function>pg_identify_object</function>.
25550 <parameter>classid</parameter> is the OID of the system catalog
25551 containing the object;
25552 <parameter>objid</parameter> is the OID of the object itself, and
25553 <parameter>objsubid</parameter> is the sub-object ID, or zero if none.
25554 This function is the inverse
25555 of <function>pg_identify_object_as_address</function>.
25556 Undefined objects are identified with <literal>NULL</literal> values.
25557 </para></entry>
25558 </row>
25559 </tbody>
25560 </tgroup>
25561 </table>
25563 <indexterm>
25564 <primary>comment</primary>
25565 <secondary sortas="database objects">about database objects</secondary>
25566 </indexterm>
25568 <para>
25569 The functions shown in <xref linkend="functions-info-comment-table"/>
25570 extract comments previously stored with the <xref linkend="sql-comment"/>
25571 command. A null value is returned if no
25572 comment could be found for the specified parameters.
25573 </para>
25575 <table id="functions-info-comment-table">
25576 <title>Comment Information Functions</title>
25577 <tgroup cols="1">
25578 <thead>
25579 <row>
25580 <entry role="func_table_entry"><para role="func_signature">
25581 Function
25582 </para>
25583 <para>
25584 Description
25585 </para></entry>
25586 </row>
25587 </thead>
25589 <tbody>
25590 <row>
25591 <entry role="func_table_entry"><para role="func_signature">
25592 <indexterm>
25593 <primary>col_description</primary>
25594 </indexterm>
25595 <function>col_description</function> ( <parameter>table</parameter> <type>oid</type>, <parameter>column</parameter> <type>integer</type> )
25596 <returnvalue>text</returnvalue>
25597 </para>
25598 <para>
25599 Returns the comment for a table column, which is specified by the OID
25600 of its table and its column number.
25601 (<function>obj_description</function> cannot be used for table
25602 columns, since columns do not have OIDs of their own.)
25603 </para></entry>
25604 </row>
25606 <row>
25607 <entry role="func_table_entry"><para role="func_signature">
25608 <indexterm>
25609 <primary>obj_description</primary>
25610 </indexterm>
25611 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
25612 <returnvalue>text</returnvalue>
25613 </para>
25614 <para>
25615 Returns the comment for a database object specified by its OID and the
25616 name of the containing system catalog. For
25617 example, <literal>obj_description(123456, 'pg_class')</literal> would
25618 retrieve the comment for the table with OID 123456.
25619 </para></entry>
25620 </row>
25622 <row>
25623 <entry role="func_table_entry"><para role="func_signature">
25624 <function>obj_description</function> ( <parameter>object</parameter> <type>oid</type> )
25625 <returnvalue>text</returnvalue>
25626 </para>
25627 <para>
25628 Returns the comment for a database object specified by its OID alone.
25629 This is <emphasis>deprecated</emphasis> since there is no guarantee
25630 that OIDs are unique across different system catalogs; therefore, the
25631 wrong comment might be returned.
25632 </para></entry>
25633 </row>
25635 <row>
25636 <entry role="func_table_entry"><para role="func_signature">
25637 <indexterm>
25638 <primary>shobj_description</primary>
25639 </indexterm>
25640 <function>shobj_description</function> ( <parameter>object</parameter> <type>oid</type>, <parameter>catalog</parameter> <type>name</type> )
25641 <returnvalue>text</returnvalue>
25642 </para>
25643 <para>
25644 Returns the comment for a shared database object specified by its OID
25645 and the name of the containing system catalog. This is just
25646 like <function>obj_description</function> except that it is used for
25647 retrieving comments on shared objects (that is, databases, roles, and
25648 tablespaces). Some system catalogs are global to all databases within
25649 each cluster, and the descriptions for objects in them are stored
25650 globally as well.
25651 </para></entry>
25652 </row>
25653 </tbody>
25654 </tgroup>
25655 </table>
25657 <para>
25658 The functions shown in <xref linkend="functions-pg-snapshot"/>
25659 provide server transaction information in an exportable form. The main
25660 use of these functions is to determine which transactions were committed
25661 between two snapshots.
25662 </para>
25664 <table id="functions-pg-snapshot">
25665 <title>Transaction ID and Snapshot Information Functions</title>
25666 <tgroup cols="1">
25667 <thead>
25668 <row>
25669 <entry role="func_table_entry"><para role="func_signature">
25670 Function
25671 </para>
25672 <para>
25673 Description
25674 </para></entry>
25675 </row>
25676 </thead>
25678 <tbody>
25679 <row>
25680 <entry role="func_table_entry"><para role="func_signature">
25681 <indexterm>
25682 <primary>pg_current_xact_id</primary>
25683 </indexterm>
25684 <function>pg_current_xact_id</function> ()
25685 <returnvalue>xid8</returnvalue>
25686 </para>
25687 <para>
25688 Returns the current transaction's ID. It will assign a new one if the
25689 current transaction does not have one already (because it has not
25690 performed any database updates).
25691 </para></entry>
25692 </row>
25694 <row>
25695 <entry role="func_table_entry"><para role="func_signature">
25696 <indexterm>
25697 <primary>pg_current_xact_id_if_assigned</primary>
25698 </indexterm>
25699 <function>pg_current_xact_id_if_assigned</function> ()
25700 <returnvalue>xid8</returnvalue>
25701 </para>
25702 <para>
25703 Returns the current transaction's ID, or <literal>NULL</literal> if no
25704 ID is assigned yet. (It's best to use this variant if the transaction
25705 might otherwise be read-only, to avoid unnecessary consumption of an
25706 XID.)
25707 </para></entry>
25708 </row>
25710 <row>
25711 <entry role="func_table_entry"><para role="func_signature">
25712 <indexterm>
25713 <primary>pg_xact_status</primary>
25714 </indexterm>
25715 <function>pg_xact_status</function> ( <type>xid8</type> )
25716 <returnvalue>text</returnvalue>
25717 </para>
25718 <para>
25719 Reports the commit status of a recent transaction.
25720 The result is one of <literal>in progress</literal>,
25721 <literal>committed</literal>, or <literal>aborted</literal>,
25722 provided that the transaction is recent enough that the system retains
25723 the commit status of that transaction.
25724 If it is old enough that no references to the transaction survive in
25725 the system and the commit status information has been discarded, the
25726 result is <literal>NULL</literal>.
25727 Applications might use this function, for example, to determine
25728 whether their transaction committed or aborted after the application
25729 and database server become disconnected while
25730 a <literal>COMMIT</literal> is in progress.
25731 Note that prepared transactions are reported as <literal>in
25732 progress</literal>; applications must check <link
25733 linkend="view-pg-prepared-xacts"><structname>pg_prepared_xacts</structname></link>
25734 if they need to determine whether a transaction ID belongs to a
25735 prepared transaction.
25736 </para></entry>
25737 </row>
25739 <row>
25740 <entry role="func_table_entry"><para role="func_signature">
25741 <indexterm>
25742 <primary>pg_current_snapshot</primary>
25743 </indexterm>
25744 <function>pg_current_snapshot</function> ()
25745 <returnvalue>pg_snapshot</returnvalue>
25746 </para>
25747 <para>
25748 Returns a current <firstterm>snapshot</firstterm>, a data structure
25749 showing which transaction IDs are now in-progress.
25750 </para></entry>
25751 </row>
25753 <row>
25754 <entry role="func_table_entry"><para role="func_signature">
25755 <indexterm>
25756 <primary>pg_snapshot_xip</primary>
25757 </indexterm>
25758 <function>pg_snapshot_xip</function> ( <type>pg_snapshot</type> )
25759 <returnvalue>setof xid8</returnvalue>
25760 </para>
25761 <para>
25762 Returns the set of in-progress transaction IDs contained in a snapshot.
25763 </para></entry>
25764 </row>
25766 <row>
25767 <entry role="func_table_entry"><para role="func_signature">
25768 <indexterm>
25769 <primary>pg_snapshot_xmax</primary>
25770 </indexterm>
25771 <function>pg_snapshot_xmax</function> ( <type>pg_snapshot</type> )
25772 <returnvalue>xid8</returnvalue>
25773 </para>
25774 <para>
25775 Returns the <structfield>xmax</structfield> of a snapshot.
25776 </para></entry>
25777 </row>
25779 <row>
25780 <entry role="func_table_entry"><para role="func_signature">
25781 <indexterm>
25782 <primary>pg_snapshot_xmin</primary>
25783 </indexterm>
25784 <function>pg_snapshot_xmin</function> ( <type>pg_snapshot</type> )
25785 <returnvalue>xid8</returnvalue>
25786 </para>
25787 <para>
25788 Returns the <structfield>xmin</structfield> of a snapshot.
25789 </para></entry>
25790 </row>
25792 <row>
25793 <entry role="func_table_entry"><para role="func_signature">
25794 <indexterm>
25795 <primary>pg_visible_in_snapshot</primary>
25796 </indexterm>
25797 <function>pg_visible_in_snapshot</function> ( <type>xid8</type>, <type>pg_snapshot</type> )
25798 <returnvalue>boolean</returnvalue>
25799 </para>
25800 <para>
25801 Is the given transaction ID <firstterm>visible</firstterm> according
25802 to this snapshot (that is, was it completed before the snapshot was
25803 taken)? Note that this function will not give the correct answer for
25804 a subtransaction ID.
25805 </para></entry>
25806 </row>
25807 </tbody>
25808 </tgroup>
25809 </table>
25811 <para>
25812 The internal transaction ID type <type>xid</type> is 32 bits wide and
25813 wraps around every 4 billion transactions. However,
25814 the functions shown in <xref linkend="functions-pg-snapshot"/> use a
25815 64-bit type <type>xid8</type> that does not wrap around during the life
25816 of an installation, and can be converted to <type>xid</type> by casting if
25817 required. The data type <type>pg_snapshot</type> stores information about
25818 transaction ID visibility at a particular moment in time. Its components
25819 are described in <xref linkend="functions-pg-snapshot-parts"/>.
25820 <type>pg_snapshot</type>'s textual representation is
25821 <literal><replaceable>xmin</replaceable>:<replaceable>xmax</replaceable>:<replaceable>xip_list</replaceable></literal>.
25822 For example <literal>10:20:10,14,15</literal> means
25823 <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
25824 </para>
25826 <table id="functions-pg-snapshot-parts">
25827 <title>Snapshot Components</title>
25828 <tgroup cols="2">
25829 <thead>
25830 <row>
25831 <entry>Name</entry>
25832 <entry>Description</entry>
25833 </row>
25834 </thead>
25836 <tbody>
25837 <row>
25838 <entry><structfield>xmin</structfield></entry>
25839 <entry>
25840 Lowest transaction ID that was still active. All transaction IDs
25841 less than <structfield>xmin</structfield> are either committed and visible,
25842 or rolled back and dead.
25843 </entry>
25844 </row>
25846 <row>
25847 <entry><structfield>xmax</structfield></entry>
25848 <entry>
25849 One past the highest completed transaction ID. All transaction IDs
25850 greater than or equal to <structfield>xmax</structfield> had not yet
25851 completed as of the time of the snapshot, and thus are invisible.
25852 </entry>
25853 </row>
25855 <row>
25856 <entry><structfield>xip_list</structfield></entry>
25857 <entry>
25858 Transactions in progress at the time of the snapshot. A transaction
25859 ID that is <literal>xmin &lt;= <replaceable>X</replaceable> &lt;
25860 xmax</literal> and not in this list was already completed at the time
25861 of the snapshot, and thus is either visible or dead according to its
25862 commit status. This list does not include the transaction IDs of
25863 subtransactions.
25864 </entry>
25865 </row>
25866 </tbody>
25867 </tgroup>
25868 </table>
25870 <para>
25871 In releases of <productname>PostgreSQL</productname> before 13 there was
25872 no <type>xid8</type> type, so variants of these functions were provided
25873 that used <type>bigint</type> to represent a 64-bit XID, with a
25874 correspondingly distinct snapshot data type <type>txid_snapshot</type>.
25875 These older functions have <literal>txid</literal> in their names. They
25876 are still supported for backward compatibility, but may be removed from a
25877 future release. See <xref linkend="functions-txid-snapshot"/>.
25878 </para>
25880 <table id="functions-txid-snapshot">
25881 <title>Deprecated Transaction ID and Snapshot Information Functions</title>
25882 <tgroup cols="1">
25883 <thead>
25884 <row>
25885 <entry role="func_table_entry"><para role="func_signature">
25886 Function
25887 </para>
25888 <para>
25889 Description
25890 </para></entry>
25891 </row>
25892 </thead>
25894 <tbody>
25895 <row>
25896 <entry role="func_table_entry"><para role="func_signature">
25897 <indexterm>
25898 <primary>txid_current</primary>
25899 </indexterm>
25900 <function>txid_current</function> ()
25901 <returnvalue>bigint</returnvalue>
25902 </para>
25903 <para>
25904 See <function>pg_current_xact_id()</function>.
25905 </para></entry>
25906 </row>
25908 <row>
25909 <entry role="func_table_entry"><para role="func_signature">
25910 <indexterm>
25911 <primary>txid_current_if_assigned</primary>
25912 </indexterm>
25913 <function>txid_current_if_assigned</function> ()
25914 <returnvalue>bigint</returnvalue>
25915 </para>
25916 <para>
25917 See <function>pg_current_xact_id_if_assigned()</function>.
25918 </para></entry>
25919 </row>
25921 <row>
25922 <entry role="func_table_entry"><para role="func_signature">
25923 <indexterm>
25924 <primary>txid_current_snapshot</primary>
25925 </indexterm>
25926 <function>txid_current_snapshot</function> ()
25927 <returnvalue>txid_snapshot</returnvalue>
25928 </para>
25929 <para>
25930 See <function>pg_current_snapshot()</function>.
25931 </para></entry>
25932 </row>
25934 <row>
25935 <entry role="func_table_entry"><para role="func_signature">
25936 <indexterm>
25937 <primary>txid_snapshot_xip</primary>
25938 </indexterm>
25939 <function>txid_snapshot_xip</function> ( <type>txid_snapshot</type> )
25940 <returnvalue>setof bigint</returnvalue>
25941 </para>
25942 <para>
25943 See <function>pg_snapshot_xip()</function>.
25944 </para></entry>
25945 </row>
25947 <row>
25948 <entry role="func_table_entry"><para role="func_signature">
25949 <indexterm>
25950 <primary>txid_snapshot_xmax</primary>
25951 </indexterm>
25952 <function>txid_snapshot_xmax</function> ( <type>txid_snapshot</type> )
25953 <returnvalue>bigint</returnvalue>
25954 </para>
25955 <para>
25956 See <function>pg_snapshot_xmax()</function>.
25957 </para></entry>
25958 </row>
25960 <row>
25961 <entry role="func_table_entry"><para role="func_signature">
25962 <indexterm>
25963 <primary>txid_snapshot_xmin</primary>
25964 </indexterm>
25965 <function>txid_snapshot_xmin</function> ( <type>txid_snapshot</type> )
25966 <returnvalue>bigint</returnvalue>
25967 </para>
25968 <para>
25969 See <function>pg_snapshot_xmin()</function>.
25970 </para></entry>
25971 </row>
25973 <row>
25974 <entry role="func_table_entry"><para role="func_signature">
25975 <indexterm>
25976 <primary>txid_visible_in_snapshot</primary>
25977 </indexterm>
25978 <function>txid_visible_in_snapshot</function> ( <type>bigint</type>, <type>txid_snapshot</type> )
25979 <returnvalue>boolean</returnvalue>
25980 </para>
25981 <para>
25982 See <function>pg_visible_in_snapshot()</function>.
25983 </para></entry>
25984 </row>
25986 <row>
25987 <entry role="func_table_entry"><para role="func_signature">
25988 <indexterm>
25989 <primary>txid_status</primary>
25990 </indexterm>
25991 <function>txid_status</function> ( <type>bigint</type> )
25992 <returnvalue>text</returnvalue>
25993 </para>
25994 <para>
25995 See <function>pg_xact_status()</function>.
25996 </para></entry>
25997 </row>
25998 </tbody>
25999 </tgroup>
26000 </table>
26002 <para>
26003 The functions shown in <xref linkend="functions-commit-timestamp"/>
26004 provide information about when past transactions were committed.
26005 They only provide useful data when the
26006 <xref linkend="guc-track-commit-timestamp"/> configuration option is
26007 enabled, and only for transactions that were committed after it was
26008 enabled.
26009 </para>
26011 <table id="functions-commit-timestamp">
26012 <title>Committed Transaction Information Functions</title>
26013 <tgroup cols="1">
26014 <thead>
26015 <row>
26016 <entry role="func_table_entry"><para role="func_signature">
26017 Function
26018 </para>
26019 <para>
26020 Description
26021 </para></entry>
26022 </row>
26023 </thead>
26025 <tbody>
26026 <row>
26027 <entry role="func_table_entry"><para role="func_signature">
26028 <indexterm>
26029 <primary>pg_xact_commit_timestamp</primary>
26030 </indexterm>
26031 <function>pg_xact_commit_timestamp</function> ( <type>xid</type> )
26032 <returnvalue>timestamp with time zone</returnvalue>
26033 </para>
26034 <para>
26035 Returns the commit timestamp of a transaction.
26036 </para></entry>
26037 </row>
26039 <row>
26040 <entry role="func_table_entry"><para role="func_signature">
26041 <indexterm>
26042 <primary>pg_xact_commit_timestamp_origin</primary>
26043 </indexterm>
26044 <function>pg_xact_commit_timestamp_origin</function> ( <type>xid</type> )
26045 <returnvalue>record</returnvalue>
26046 ( <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
26047 <parameter>roident</parameter> <type>oid</type>)
26048 </para>
26049 <para>
26050 Returns the commit timestamp and replication origin of a transaction.
26051 </para></entry>
26052 </row>
26054 <row>
26055 <entry role="func_table_entry"><para role="func_signature">
26056 <indexterm>
26057 <primary>pg_last_committed_xact</primary>
26058 </indexterm>
26059 <function>pg_last_committed_xact</function> ()
26060 <returnvalue>record</returnvalue>
26061 ( <parameter>xid</parameter> <type>xid</type>,
26062 <parameter>timestamp</parameter> <type>timestamp with time zone</type>,
26063 <parameter>roident</parameter> <type>oid</type> )
26064 </para>
26065 <para>
26066 Returns the transaction ID, commit timestamp and replication origin
26067 of the latest committed transaction.
26068 </para></entry>
26069 </row>
26070 </tbody>
26071 </tgroup>
26072 </table>
26074 <para>
26075 The functions shown in <xref linkend="functions-controldata"/>
26076 print information initialized during <command>initdb</command>, such
26077 as the catalog version. They also show information about write-ahead
26078 logging and checkpoint processing. This information is cluster-wide,
26079 not specific to any one database. These functions provide most of the same
26080 information, from the same source, as the
26081 <xref linkend="app-pgcontroldata"/> application.
26082 </para>
26084 <table id="functions-controldata">
26085 <title>Control Data Functions</title>
26086 <tgroup cols="1">
26087 <thead>
26088 <row>
26089 <entry role="func_table_entry"><para role="func_signature">
26090 Function
26091 </para>
26092 <para>
26093 Description
26094 </para></entry>
26095 </row>
26096 </thead>
26098 <tbody>
26099 <row>
26100 <entry role="func_table_entry"><para role="func_signature">
26101 <indexterm>
26102 <primary>pg_control_checkpoint</primary>
26103 </indexterm>
26104 <function>pg_control_checkpoint</function> ()
26105 <returnvalue>record</returnvalue>
26106 </para>
26107 <para>
26108 Returns information about current checkpoint state, as shown in
26109 <xref linkend="functions-pg-control-checkpoint"/>.
26110 </para></entry>
26111 </row>
26113 <row>
26114 <entry role="func_table_entry"><para role="func_signature">
26115 <indexterm>
26116 <primary>pg_control_system</primary>
26117 </indexterm>
26118 <function>pg_control_system</function> ()
26119 <returnvalue>record</returnvalue>
26120 </para>
26121 <para>
26122 Returns information about current control file state, as shown in
26123 <xref linkend="functions-pg-control-system"/>.
26124 </para></entry>
26125 </row>
26127 <row>
26128 <entry role="func_table_entry"><para role="func_signature">
26129 <indexterm>
26130 <primary>pg_control_init</primary>
26131 </indexterm>
26132 <function>pg_control_init</function> ()
26133 <returnvalue>record</returnvalue>
26134 </para>
26135 <para>
26136 Returns information about cluster initialization state, as shown in
26137 <xref linkend="functions-pg-control-init"/>.
26138 </para></entry>
26139 </row>
26141 <row>
26142 <entry role="func_table_entry"><para role="func_signature">
26143 <indexterm>
26144 <primary>pg_control_recovery</primary>
26145 </indexterm>
26146 <function>pg_control_recovery</function> ()
26147 <returnvalue>record</returnvalue>
26148 </para>
26149 <para>
26150 Returns information about recovery state, as shown in
26151 <xref linkend="functions-pg-control-recovery"/>.
26152 </para></entry>
26153 </row>
26154 </tbody>
26155 </tgroup>
26156 </table>
26158 <table id="functions-pg-control-checkpoint">
26159 <title><function>pg_control_checkpoint</function> Output Columns</title>
26160 <tgroup cols="2">
26161 <thead>
26162 <row>
26163 <entry>Column Name</entry>
26164 <entry>Data Type</entry>
26165 </row>
26166 </thead>
26168 <tbody>
26170 <row>
26171 <entry><structfield>checkpoint_lsn</structfield></entry>
26172 <entry><type>pg_lsn</type></entry>
26173 </row>
26175 <row>
26176 <entry><structfield>redo_lsn</structfield></entry>
26177 <entry><type>pg_lsn</type></entry>
26178 </row>
26180 <row>
26181 <entry><structfield>redo_wal_file</structfield></entry>
26182 <entry><type>text</type></entry>
26183 </row>
26185 <row>
26186 <entry><structfield>timeline_id</structfield></entry>
26187 <entry><type>integer</type></entry>
26188 </row>
26190 <row>
26191 <entry><structfield>prev_timeline_id</structfield></entry>
26192 <entry><type>integer</type></entry>
26193 </row>
26195 <row>
26196 <entry><structfield>full_page_writes</structfield></entry>
26197 <entry><type>boolean</type></entry>
26198 </row>
26200 <row>
26201 <entry><structfield>next_xid</structfield></entry>
26202 <entry><type>text</type></entry>
26203 </row>
26205 <row>
26206 <entry><structfield>next_oid</structfield></entry>
26207 <entry><type>oid</type></entry>
26208 </row>
26210 <row>
26211 <entry><structfield>next_multixact_id</structfield></entry>
26212 <entry><type>xid</type></entry>
26213 </row>
26215 <row>
26216 <entry><structfield>next_multi_offset</structfield></entry>
26217 <entry><type>xid</type></entry>
26218 </row>
26220 <row>
26221 <entry><structfield>oldest_xid</structfield></entry>
26222 <entry><type>xid</type></entry>
26223 </row>
26225 <row>
26226 <entry><structfield>oldest_xid_dbid</structfield></entry>
26227 <entry><type>oid</type></entry>
26228 </row>
26230 <row>
26231 <entry><structfield>oldest_active_xid</structfield></entry>
26232 <entry><type>xid</type></entry>
26233 </row>
26235 <row>
26236 <entry><structfield>oldest_multi_xid</structfield></entry>
26237 <entry><type>xid</type></entry>
26238 </row>
26240 <row>
26241 <entry><structfield>oldest_multi_dbid</structfield></entry>
26242 <entry><type>oid</type></entry>
26243 </row>
26245 <row>
26246 <entry><structfield>oldest_commit_ts_xid</structfield></entry>
26247 <entry><type>xid</type></entry>
26248 </row>
26250 <row>
26251 <entry><structfield>newest_commit_ts_xid</structfield></entry>
26252 <entry><type>xid</type></entry>
26253 </row>
26255 <row>
26256 <entry><structfield>checkpoint_time</structfield></entry>
26257 <entry><type>timestamp with time zone</type></entry>
26258 </row>
26260 </tbody>
26261 </tgroup>
26262 </table>
26264 <table id="functions-pg-control-system">
26265 <title><function>pg_control_system</function> Output Columns</title>
26266 <tgroup cols="2">
26267 <thead>
26268 <row>
26269 <entry>Column Name</entry>
26270 <entry>Data Type</entry>
26271 </row>
26272 </thead>
26274 <tbody>
26276 <row>
26277 <entry><structfield>pg_control_version</structfield></entry>
26278 <entry><type>integer</type></entry>
26279 </row>
26281 <row>
26282 <entry><structfield>catalog_version_no</structfield></entry>
26283 <entry><type>integer</type></entry>
26284 </row>
26286 <row>
26287 <entry><structfield>system_identifier</structfield></entry>
26288 <entry><type>bigint</type></entry>
26289 </row>
26291 <row>
26292 <entry><structfield>pg_control_last_modified</structfield></entry>
26293 <entry><type>timestamp with time zone</type></entry>
26294 </row>
26296 </tbody>
26297 </tgroup>
26298 </table>
26300 <table id="functions-pg-control-init">
26301 <title><function>pg_control_init</function> Output Columns</title>
26302 <tgroup cols="2">
26303 <thead>
26304 <row>
26305 <entry>Column Name</entry>
26306 <entry>Data Type</entry>
26307 </row>
26308 </thead>
26310 <tbody>
26312 <row>
26313 <entry><structfield>max_data_alignment</structfield></entry>
26314 <entry><type>integer</type></entry>
26315 </row>
26317 <row>
26318 <entry><structfield>database_block_size</structfield></entry>
26319 <entry><type>integer</type></entry>
26320 </row>
26322 <row>
26323 <entry><structfield>blocks_per_segment</structfield></entry>
26324 <entry><type>integer</type></entry>
26325 </row>
26327 <row>
26328 <entry><structfield>wal_block_size</structfield></entry>
26329 <entry><type>integer</type></entry>
26330 </row>
26332 <row>
26333 <entry><structfield>bytes_per_wal_segment</structfield></entry>
26334 <entry><type>integer</type></entry>
26335 </row>
26337 <row>
26338 <entry><structfield>max_identifier_length</structfield></entry>
26339 <entry><type>integer</type></entry>
26340 </row>
26342 <row>
26343 <entry><structfield>max_index_columns</structfield></entry>
26344 <entry><type>integer</type></entry>
26345 </row>
26347 <row>
26348 <entry><structfield>max_toast_chunk_size</structfield></entry>
26349 <entry><type>integer</type></entry>
26350 </row>
26352 <row>
26353 <entry><structfield>large_object_chunk_size</structfield></entry>
26354 <entry><type>integer</type></entry>
26355 </row>
26357 <row>
26358 <entry><structfield>float8_pass_by_value</structfield></entry>
26359 <entry><type>boolean</type></entry>
26360 </row>
26362 <row>
26363 <entry><structfield>data_page_checksum_version</structfield></entry>
26364 <entry><type>integer</type></entry>
26365 </row>
26367 </tbody>
26368 </tgroup>
26369 </table>
26371 <table id="functions-pg-control-recovery">
26372 <title><function>pg_control_recovery</function> Output Columns</title>
26373 <tgroup cols="2">
26374 <thead>
26375 <row>
26376 <entry>Column Name</entry>
26377 <entry>Data Type</entry>
26378 </row>
26379 </thead>
26381 <tbody>
26383 <row>
26384 <entry><structfield>min_recovery_end_lsn</structfield></entry>
26385 <entry><type>pg_lsn</type></entry>
26386 </row>
26388 <row>
26389 <entry><structfield>min_recovery_end_timeline</structfield></entry>
26390 <entry><type>integer</type></entry>
26391 </row>
26393 <row>
26394 <entry><structfield>backup_start_lsn</structfield></entry>
26395 <entry><type>pg_lsn</type></entry>
26396 </row>
26398 <row>
26399 <entry><structfield>backup_end_lsn</structfield></entry>
26400 <entry><type>pg_lsn</type></entry>
26401 </row>
26403 <row>
26404 <entry><structfield>end_of_backup_record_required</structfield></entry>
26405 <entry><type>boolean</type></entry>
26406 </row>
26408 </tbody>
26409 </tgroup>
26410 </table>
26412 </sect1>
26414 <sect1 id="functions-admin">
26415 <title>System Administration Functions</title>
26417 <para>
26418 The functions described in this section are used to control and
26419 monitor a <productname>PostgreSQL</productname> installation.
26420 </para>
26422 <sect2 id="functions-admin-set">
26423 <title>Configuration Settings Functions</title>
26425 <indexterm>
26426 <primary>SET</primary>
26427 </indexterm>
26429 <indexterm>
26430 <primary>SHOW</primary>
26431 </indexterm>
26433 <indexterm>
26434 <primary>configuration</primary>
26435 <secondary sortas="server">of the server</secondary>
26436 <tertiary>functions</tertiary>
26437 </indexterm>
26439 <para>
26440 <xref linkend="functions-admin-set-table"/> shows the functions
26441 available to query and alter run-time configuration parameters.
26442 </para>
26444 <table id="functions-admin-set-table">
26445 <title>Configuration Settings Functions</title>
26446 <tgroup cols="1">
26447 <thead>
26448 <row>
26449 <entry role="func_table_entry"><para role="func_signature">
26450 Function
26451 </para>
26452 <para>
26453 Description
26454 </para>
26455 <para>
26456 Example(s)
26457 </para></entry>
26458 </row>
26459 </thead>
26461 <tbody>
26462 <row>
26463 <entry role="func_table_entry"><para role="func_signature">
26464 <indexterm>
26465 <primary>current_setting</primary>
26466 </indexterm>
26467 <function>current_setting</function> ( <parameter>setting_name</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
26468 <returnvalue>text</returnvalue>
26469 </para>
26470 <para>
26471 Returns the current value of the
26472 setting <parameter>setting_name</parameter>. If there is no such
26473 setting, <function>current_setting</function> throws an error
26474 unless <parameter>missing_ok</parameter> is supplied and
26475 is <literal>true</literal> (in which case NULL is returned).
26476 This function corresponds to
26477 the <acronym>SQL</acronym> command <xref linkend="sql-show"/>.
26478 </para>
26479 <para>
26480 <literal>current_setting('datestyle')</literal>
26481 <returnvalue>ISO, MDY</returnvalue>
26482 </para></entry>
26483 </row>
26485 <row>
26486 <entry role="func_table_entry"><para role="func_signature">
26487 <indexterm>
26488 <primary>set_config</primary>
26489 </indexterm>
26490 <function>set_config</function> (
26491 <parameter>setting_name</parameter> <type>text</type>,
26492 <parameter>new_value</parameter> <type>text</type>,
26493 <parameter>is_local</parameter> <type>boolean</type> )
26494 <returnvalue>text</returnvalue>
26495 </para>
26496 <para>
26497 Sets the parameter <parameter>setting_name</parameter>
26498 to <parameter>new_value</parameter>, and returns that value.
26499 If <parameter>is_local</parameter> is <literal>true</literal>, the new
26500 value will only apply during the current transaction. If you want the
26501 new value to apply for the rest of the current session,
26502 use <literal>false</literal> instead. This function corresponds to
26503 the SQL command <xref linkend="sql-set"/>.
26504 </para>
26505 <para>
26506 <literal>set_config('log_statement_stats', 'off', false)</literal>
26507 <returnvalue>off</returnvalue>
26508 </para></entry>
26509 </row>
26510 </tbody>
26511 </tgroup>
26512 </table>
26514 </sect2>
26516 <sect2 id="functions-admin-signal">
26517 <title>Server Signaling Functions</title>
26519 <indexterm>
26520 <primary>signal</primary>
26521 <secondary sortas="backend">backend processes</secondary>
26522 </indexterm>
26524 <para>
26525 The functions shown in <xref
26526 linkend="functions-admin-signal-table"/> send control signals to
26527 other server processes. Use of these functions is restricted to
26528 superusers by default but access may be granted to others using
26529 <command>GRANT</command>, with noted exceptions.
26530 </para>
26532 <para>
26533 Each of these functions returns <literal>true</literal> if
26534 the signal was successfully sent and <literal>false</literal>
26535 if sending the signal failed.
26536 </para>
26538 <table id="functions-admin-signal-table">
26539 <title>Server Signaling Functions</title>
26540 <tgroup cols="1">
26541 <thead>
26542 <row>
26543 <entry role="func_table_entry"><para role="func_signature">
26544 Function
26545 </para>
26546 <para>
26547 Description
26548 </para></entry>
26549 </row>
26550 </thead>
26552 <tbody>
26553 <row>
26554 <entry role="func_table_entry"><para role="func_signature">
26555 <indexterm>
26556 <primary>pg_cancel_backend</primary>
26557 </indexterm>
26558 <function>pg_cancel_backend</function> ( <parameter>pid</parameter> <type>integer</type> )
26559 <returnvalue>boolean</returnvalue>
26560 </para>
26561 <para>
26562 Cancels the current query of the session whose backend process has the
26563 specified process ID. This is also allowed if the
26564 calling role is a member of the role whose backend is being canceled or
26565 the calling role has privileges of <literal>pg_signal_backend</literal>,
26566 however only superusers can cancel superuser backends.
26567 </para></entry>
26568 </row>
26570 <row>
26571 <entry role="func_table_entry"><para role="func_signature">
26572 <indexterm>
26573 <primary>pg_log_backend_memory_contexts</primary>
26574 </indexterm>
26575 <function>pg_log_backend_memory_contexts</function> ( <parameter>pid</parameter> <type>integer</type> )
26576 <returnvalue>boolean</returnvalue>
26577 </para>
26578 <para>
26579 Requests to log the memory contexts of the backend with the
26580 specified process ID. This function can send the request to
26581 backends and auxiliary processes except logger. These memory contexts
26582 will be logged at
26583 <literal>LOG</literal> message level. They will appear in
26584 the server log based on the log configuration set
26585 (See <xref linkend="runtime-config-logging"/> for more information),
26586 but will not be sent to the client regardless of
26587 <xref linkend="guc-client-min-messages"/>.
26588 </para></entry>
26589 </row>
26591 <row>
26592 <entry role="func_table_entry"><para role="func_signature">
26593 <indexterm>
26594 <primary>pg_reload_conf</primary>
26595 </indexterm>
26596 <function>pg_reload_conf</function> ()
26597 <returnvalue>boolean</returnvalue>
26598 </para>
26599 <para>
26600 Causes all processes of the <productname>PostgreSQL</productname>
26601 server to reload their configuration files. (This is initiated by
26602 sending a <systemitem>SIGHUP</systemitem> signal to the postmaster
26603 process, which in turn sends <systemitem>SIGHUP</systemitem> to each
26604 of its children.) You can use the
26605 <link linkend="view-pg-file-settings"><structname>pg_file_settings</structname></link>,
26606 <link linkend="view-pg-hba-file-rules"><structname>pg_hba_file_rules</structname></link> and
26607 <link linkend="view-pg-hba-file-rules"><structname>pg_ident_file_mappings</structname></link> views
26608 to check the configuration files for possible errors, before reloading.
26609 </para></entry>
26610 </row>
26612 <row>
26613 <entry role="func_table_entry"><para role="func_signature">
26614 <indexterm>
26615 <primary>pg_rotate_logfile</primary>
26616 </indexterm>
26617 <function>pg_rotate_logfile</function> ()
26618 <returnvalue>boolean</returnvalue>
26619 </para>
26620 <para>
26621 Signals the log-file manager to switch to a new output file
26622 immediately. This works only when the built-in log collector is
26623 running, since otherwise there is no log-file manager subprocess.
26624 </para></entry>
26625 </row>
26627 <row>
26628 <entry role="func_table_entry"><para role="func_signature">
26629 <indexterm>
26630 <primary>pg_terminate_backend</primary>
26631 </indexterm>
26632 <function>pg_terminate_backend</function> ( <parameter>pid</parameter> <type>integer</type>, <parameter>timeout</parameter> <type>bigint</type> <literal>DEFAULT</literal> <literal>0</literal> )
26633 <returnvalue>boolean</returnvalue>
26634 </para>
26635 <para>
26636 Terminates the session whose backend process has the
26637 specified process ID. This is also allowed if the calling role
26638 is a member of the role whose backend is being terminated or the
26639 calling role has privileges of <literal>pg_signal_backend</literal>,
26640 however only superusers can terminate superuser backends.
26641 </para>
26642 <para>
26643 If <parameter>timeout</parameter> is not specified or zero, this
26644 function returns <literal>true</literal> whether the process actually
26645 terminates or not, indicating only that the sending of the signal was
26646 successful. If the <parameter>timeout</parameter> is specified (in
26647 milliseconds) and greater than zero, the function waits until the
26648 process is actually terminated or until the given time has passed. If
26649 the process is terminated, the function
26650 returns <literal>true</literal>. On timeout, a warning is emitted and
26651 <literal>false</literal> is returned.
26652 </para></entry>
26653 </row>
26654 </tbody>
26655 </tgroup>
26656 </table>
26658 <para>
26659 <function>pg_cancel_backend</function> and <function>pg_terminate_backend</function>
26660 send signals (<systemitem>SIGINT</systemitem> or <systemitem>SIGTERM</systemitem>
26661 respectively) to backend processes identified by process ID.
26662 The process ID of an active backend can be found from
26663 the <structfield>pid</structfield> column of the
26664 <structname>pg_stat_activity</structname> view, or by listing the
26665 <command>postgres</command> processes on the server (using
26666 <application>ps</application> on Unix or the <application>Task
26667 Manager</application> on <productname>Windows</productname>).
26668 The role of an active backend can be found from the
26669 <structfield>usename</structfield> column of the
26670 <structname>pg_stat_activity</structname> view.
26671 </para>
26673 <para>
26674 <function>pg_log_backend_memory_contexts</function> can be used
26675 to log the memory contexts of a backend process. For example:
26676 <programlisting>
26677 postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid());
26678 pg_log_backend_memory_contexts
26679 --------------------------------
26681 (1 row)
26682 </programlisting>
26683 One message for each memory context will be logged. For example:
26684 <screen>
26685 LOG: logging memory contexts of PID 10377
26686 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid());
26687 LOG: level: 0; TopMemoryContext: 80800 total in 6 blocks; 14432 free (5 chunks); 66368 used
26688 LOG: level: 1; pgstat TabStatusArray lookup hash table: 8192 total in 1 blocks; 1408 free (0 chunks); 6784 used
26689 LOG: level: 1; TopTransactionContext: 8192 total in 1 blocks; 7720 free (1 chunks); 472 used
26690 LOG: level: 1; RowDescriptionContext: 8192 total in 1 blocks; 6880 free (0 chunks); 1312 used
26691 LOG: level: 1; MessageContext: 16384 total in 2 blocks; 5152 free (0 chunks); 11232 used
26692 LOG: level: 1; Operator class cache: 8192 total in 1 blocks; 512 free (0 chunks); 7680 used
26693 LOG: level: 1; smgr relation table: 16384 total in 2 blocks; 4544 free (3 chunks); 11840 used
26694 LOG: level: 1; TransactionAbortContext: 32768 total in 1 blocks; 32504 free (0 chunks); 264 used
26696 LOG: level: 1; ErrorContext: 8192 total in 1 blocks; 7928 free (3 chunks); 264 used
26697 LOG: Grand total: 1651920 bytes in 201 blocks; 622360 free (88 chunks); 1029560 used
26698 </screen>
26699 If there are more than 100 child contexts under the same parent, the first
26700 100 child contexts are logged, along with a summary of the remaining contexts.
26701 Note that frequent calls to this function could incur significant overhead,
26702 because it may generate a large number of log messages.
26703 </para>
26705 </sect2>
26707 <sect2 id="functions-admin-backup">
26708 <title>Backup Control Functions</title>
26710 <indexterm>
26711 <primary>backup</primary>
26712 </indexterm>
26714 <para>
26715 The functions shown in <xref
26716 linkend="functions-admin-backup-table"/> assist in making on-line backups.
26717 These functions cannot be executed during recovery (except
26718 <function>pg_backup_start</function>,
26719 <function>pg_backup_stop</function>,
26720 and <function>pg_wal_lsn_diff</function>).
26721 </para>
26723 <para>
26724 For details about proper usage of these functions, see
26725 <xref linkend="continuous-archiving"/>.
26726 </para>
26728 <table id="functions-admin-backup-table">
26729 <title>Backup Control Functions</title>
26730 <tgroup cols="1">
26731 <thead>
26732 <row>
26733 <entry role="func_table_entry"><para role="func_signature">
26734 Function
26735 </para>
26736 <para>
26737 Description
26738 </para></entry>
26739 </row>
26740 </thead>
26742 <tbody>
26743 <row>
26744 <entry role="func_table_entry"><para role="func_signature">
26745 <indexterm>
26746 <primary>pg_create_restore_point</primary>
26747 </indexterm>
26748 <function>pg_create_restore_point</function> ( <parameter>name</parameter> <type>text</type> )
26749 <returnvalue>pg_lsn</returnvalue>
26750 </para>
26751 <para>
26752 Creates a named marker record in the write-ahead log that can later be
26753 used as a recovery target, and returns the corresponding write-ahead
26754 log location. The given name can then be used with
26755 <xref linkend="guc-recovery-target-name"/> to specify the point up to
26756 which recovery will proceed. Avoid creating multiple restore points
26757 with the same name, since recovery will stop at the first one whose
26758 name matches the recovery target.
26759 </para>
26760 <para>
26761 This function is restricted to superusers by default, but other users
26762 can be granted EXECUTE to run the function.
26763 </para></entry>
26764 </row>
26766 <row>
26767 <entry role="func_table_entry"><para role="func_signature">
26768 <indexterm>
26769 <primary>pg_current_wal_flush_lsn</primary>
26770 </indexterm>
26771 <function>pg_current_wal_flush_lsn</function> ()
26772 <returnvalue>pg_lsn</returnvalue>
26773 </para>
26774 <para>
26775 Returns the current write-ahead log flush location (see notes below).
26776 </para></entry>
26777 </row>
26779 <row>
26780 <entry role="func_table_entry"><para role="func_signature">
26781 <indexterm>
26782 <primary>pg_current_wal_insert_lsn</primary>
26783 </indexterm>
26784 <function>pg_current_wal_insert_lsn</function> ()
26785 <returnvalue>pg_lsn</returnvalue>
26786 </para>
26787 <para>
26788 Returns the current write-ahead log insert location (see notes below).
26789 </para></entry>
26790 </row>
26792 <row>
26793 <entry role="func_table_entry"><para role="func_signature">
26794 <indexterm>
26795 <primary>pg_current_wal_lsn</primary>
26796 </indexterm>
26797 <function>pg_current_wal_lsn</function> ()
26798 <returnvalue>pg_lsn</returnvalue>
26799 </para>
26800 <para>
26801 Returns the current write-ahead log write location (see notes below).
26802 </para></entry>
26803 </row>
26805 <row>
26806 <entry role="func_table_entry"><para role="func_signature">
26807 <indexterm>
26808 <primary>pg_backup_start</primary>
26809 </indexterm>
26810 <function>pg_backup_start</function> (
26811 <parameter>label</parameter> <type>text</type>
26812 <optional>, <parameter>fast</parameter> <type>boolean</type>
26813 </optional> )
26814 <returnvalue>pg_lsn</returnvalue>
26815 </para>
26816 <para>
26817 Prepares the server to begin an on-line backup. The only required
26818 parameter is an arbitrary user-defined label for the backup.
26819 (Typically this would be the name under which the backup dump file
26820 will be stored.)
26821 If the optional second parameter is given as <literal>true</literal>,
26822 it specifies executing <function>pg_backup_start</function> as quickly
26823 as possible. This forces an immediate checkpoint which will cause a
26824 spike in I/O operations, slowing any concurrently executing queries.
26825 </para>
26826 <para>
26827 This function is restricted to superusers by default, but other users
26828 can be granted EXECUTE to run the function.
26829 </para></entry>
26830 </row>
26832 <row>
26833 <entry role="func_table_entry"><para role="func_signature">
26834 <indexterm>
26835 <primary>pg_backup_stop</primary>
26836 </indexterm>
26837 <function>pg_backup_stop</function> (
26838 <optional><parameter>wait_for_archive</parameter> <type>boolean</type>
26839 </optional> )
26840 <returnvalue>record</returnvalue>
26841 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
26842 <parameter>labelfile</parameter> <type>text</type>,
26843 <parameter>spcmapfile</parameter> <type>text</type> )
26844 </para>
26845 <para>
26846 Finishes performing an on-line backup. The desired contents of the
26847 backup label file and the tablespace map file are returned as part of
26848 the result of the function and must be written to files in the
26849 backup area. These files must not be written to the live data directory
26850 (doing so will cause PostgreSQL to fail to restart in the event of a
26851 crash).
26852 </para>
26853 <para>
26854 There is an optional parameter of type <type>boolean</type>.
26855 If false, the function will return immediately after the backup is
26856 completed, without waiting for WAL to be archived. This behavior is
26857 only useful with backup software that independently monitors WAL
26858 archiving. Otherwise, WAL required to make the backup consistent might
26859 be missing and make the backup useless. By default or when this
26860 parameter is true, <function>pg_backup_stop</function> will wait for
26861 WAL to be archived when archiving is enabled. (On a standby, this
26862 means that it will wait only when <varname>archive_mode</varname> =
26863 <literal>always</literal>. If write activity on the primary is low,
26864 it may be useful to run <function>pg_switch_wal</function> on the
26865 primary in order to trigger an immediate segment switch.)
26866 </para>
26867 <para>
26868 When executed on a primary, this function also creates a backup
26869 history file in the write-ahead log archive area. The history file
26870 includes the label given to <function>pg_backup_start</function>, the
26871 starting and ending write-ahead log locations for the backup, and the
26872 starting and ending times of the backup. After recording the ending
26873 location, the current write-ahead log insertion point is automatically
26874 advanced to the next write-ahead log file, so that the ending
26875 write-ahead log file can be archived immediately to complete the
26876 backup.
26877 </para>
26878 <para>
26879 The result of the function is a single record.
26880 The <parameter>lsn</parameter> column holds the backup's ending
26881 write-ahead log location (which again can be ignored). The second
26882 column returns the contents of the backup label file, and the third
26883 column returns the contents of the tablespace map file. These must be
26884 stored as part of the backup and are required as part of the restore
26885 process.
26886 </para>
26887 <para>
26888 This function is restricted to superusers by default, but other users
26889 can be granted EXECUTE to run the function.
26890 </para></entry>
26891 </row>
26893 <row>
26894 <entry role="func_table_entry"><para role="func_signature">
26895 <indexterm>
26896 <primary>pg_switch_wal</primary>
26897 </indexterm>
26898 <function>pg_switch_wal</function> ()
26899 <returnvalue>pg_lsn</returnvalue>
26900 </para>
26901 <para>
26902 Forces the server to switch to a new write-ahead log file, which
26903 allows the current file to be archived (assuming you are using
26904 continuous archiving). The result is the ending write-ahead log
26905 location plus 1 within the just-completed write-ahead log file. If
26906 there has been no write-ahead log activity since the last write-ahead
26907 log switch, <function>pg_switch_wal</function> does nothing and
26908 returns the start location of the write-ahead log file currently in
26909 use.
26910 </para>
26911 <para>
26912 This function is restricted to superusers by default, but other users
26913 can be granted EXECUTE to run the function.
26914 </para></entry>
26915 </row>
26917 <row>
26918 <entry role="func_table_entry"><para role="func_signature">
26919 <indexterm>
26920 <primary>pg_walfile_name</primary>
26921 </indexterm>
26922 <function>pg_walfile_name</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
26923 <returnvalue>text</returnvalue>
26924 </para>
26925 <para>
26926 Converts a write-ahead log location to the name of the WAL file
26927 holding that location.
26928 </para></entry>
26929 </row>
26931 <row>
26932 <entry role="func_table_entry"><para role="func_signature">
26933 <indexterm>
26934 <primary>pg_walfile_name_offset</primary>
26935 </indexterm>
26936 <function>pg_walfile_name_offset</function> ( <parameter>lsn</parameter> <type>pg_lsn</type> )
26937 <returnvalue>record</returnvalue>
26938 ( <parameter>file_name</parameter> <type>text</type>,
26939 <parameter>file_offset</parameter> <type>integer</type> )
26940 </para>
26941 <para>
26942 Converts a write-ahead log location to a WAL file name and byte offset
26943 within that file.
26944 </para></entry>
26945 </row>
26947 <row>
26948 <entry role="func_table_entry"><para role="func_signature">
26949 <indexterm>
26950 <primary>pg_wal_lsn_diff</primary>
26951 </indexterm>
26952 <function>pg_wal_lsn_diff</function> ( <parameter>lsn1</parameter> <type>pg_lsn</type>, <parameter>lsn2</parameter> <type>pg_lsn</type> )
26953 <returnvalue>numeric</returnvalue>
26954 </para>
26955 <para>
26956 Calculates the difference in bytes (<parameter>lsn1</parameter> - <parameter>lsn2</parameter>) between two write-ahead log
26957 locations. This can be used
26958 with <structname>pg_stat_replication</structname> or some of the
26959 functions shown in <xref linkend="functions-admin-backup-table"/> to
26960 get the replication lag.
26961 </para></entry>
26962 </row>
26963 </tbody>
26964 </tgroup>
26965 </table>
26967 <para>
26968 <function>pg_current_wal_lsn</function> displays the current write-ahead
26969 log write location in the same format used by the above functions.
26970 Similarly, <function>pg_current_wal_insert_lsn</function> displays the
26971 current write-ahead log insertion location
26972 and <function>pg_current_wal_flush_lsn</function> displays the current
26973 write-ahead log flush location. The insertion location is
26974 the <quote>logical</quote> end of the write-ahead log at any instant,
26975 while the write location is the end of what has actually been written out
26976 from the server's internal buffers, and the flush location is the last
26977 location known to be written to durable storage. The write location is the
26978 end of what can be examined from outside the server, and is usually what
26979 you want if you are interested in archiving partially-complete write-ahead
26980 log files. The insertion and flush locations are made available primarily
26981 for server debugging purposes. These are all read-only operations and do
26982 not require superuser permissions.
26983 </para>
26985 <para>
26986 You can use <function>pg_walfile_name_offset</function> to extract the
26987 corresponding write-ahead log file name and byte offset from
26988 a <type>pg_lsn</type> value. For example:
26989 <programlisting>
26990 postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn);
26991 file_name | file_offset
26992 --------------------------+-------------
26993 00000001000000000000000D | 4039624
26994 (1 row)
26995 </programlisting>
26996 Similarly, <function>pg_walfile_name</function> extracts just the write-ahead log file name.
26997 When the given write-ahead log location is exactly at a write-ahead log file boundary, both
26998 these functions return the name of the preceding write-ahead log file.
26999 This is usually the desired behavior for managing write-ahead log archiving
27000 behavior, since the preceding file is the last one that currently
27001 needs to be archived.
27002 </para>
27004 </sect2>
27006 <sect2 id="functions-recovery-control">
27007 <title>Recovery Control Functions</title>
27009 <para>
27010 The functions shown in <xref
27011 linkend="functions-recovery-info-table"/> provide information
27012 about the current status of a standby server.
27013 These functions may be executed both during recovery and in normal running.
27014 </para>
27016 <table id="functions-recovery-info-table">
27017 <title>Recovery Information Functions</title>
27018 <tgroup cols="1">
27019 <thead>
27020 <row>
27021 <entry role="func_table_entry"><para role="func_signature">
27022 Function
27023 </para>
27024 <para>
27025 Description
27026 </para></entry>
27027 </row>
27028 </thead>
27030 <tbody>
27031 <row>
27032 <entry role="func_table_entry"><para role="func_signature">
27033 <indexterm>
27034 <primary>pg_is_in_recovery</primary>
27035 </indexterm>
27036 <function>pg_is_in_recovery</function> ()
27037 <returnvalue>boolean</returnvalue>
27038 </para>
27039 <para>
27040 Returns true if recovery is still in progress.
27041 </para></entry>
27042 </row>
27044 <row>
27045 <entry role="func_table_entry"><para role="func_signature">
27046 <indexterm>
27047 <primary>pg_last_wal_receive_lsn</primary>
27048 </indexterm>
27049 <function>pg_last_wal_receive_lsn</function> ()
27050 <returnvalue>pg_lsn</returnvalue>
27051 </para>
27052 <para>
27053 Returns the last write-ahead log location that has been received and
27054 synced to disk by streaming replication. While streaming replication
27055 is in progress this will increase monotonically. If recovery has
27056 completed then this will remain static at the location of the last WAL
27057 record received and synced to disk during recovery. If streaming
27058 replication is disabled, or if it has not yet started, the function
27059 returns <literal>NULL</literal>.
27060 </para></entry>
27061 </row>
27063 <row>
27064 <entry role="func_table_entry"><para role="func_signature">
27065 <indexterm>
27066 <primary>pg_last_wal_replay_lsn</primary>
27067 </indexterm>
27068 <function>pg_last_wal_replay_lsn</function> ()
27069 <returnvalue>pg_lsn</returnvalue>
27070 </para>
27071 <para>
27072 Returns the last write-ahead log location that has been replayed
27073 during recovery. If recovery is still in progress this will increase
27074 monotonically. If recovery has completed then this will remain
27075 static at the location of the last WAL record applied during recovery.
27076 When the server has been started normally without recovery, the
27077 function returns <literal>NULL</literal>.
27078 </para></entry>
27079 </row>
27081 <row>
27082 <entry role="func_table_entry"><para role="func_signature">
27083 <indexterm>
27084 <primary>pg_last_xact_replay_timestamp</primary>
27085 </indexterm>
27086 <function>pg_last_xact_replay_timestamp</function> ()
27087 <returnvalue>timestamp with time zone</returnvalue>
27088 </para>
27089 <para>
27090 Returns the time stamp of the last transaction replayed during
27091 recovery. This is the time at which the commit or abort WAL record
27092 for that transaction was generated on the primary. If no transactions
27093 have been replayed during recovery, the function
27094 returns <literal>NULL</literal>. Otherwise, if recovery is still in
27095 progress this will increase monotonically. If recovery has completed
27096 then this will remain static at the time of the last transaction
27097 applied during recovery. When the server has been started normally
27098 without recovery, the function returns <literal>NULL</literal>.
27099 </para></entry>
27100 </row>
27102 <row>
27103 <entry role="func_table_entry"><para role="func_signature">
27104 <indexterm>
27105 <primary>pg_get_wal_resource_managers</primary>
27106 </indexterm>
27107 <function>pg_get_wal_resource_managers</function> ()
27108 <returnvalue>setof record</returnvalue>
27109 ( <parameter>rm_id</parameter> <type>integer</type>,
27110 <parameter>rm_name</parameter> <type>text</type>,
27111 <parameter>rm_builtin</parameter> <type>boolean</type> )
27112 </para>
27113 <para>
27114 Returns the currently-loaded WAL resource managers in the system. The
27115 column <parameter>rm_builtin</parameter> indicates whether it's a
27116 built-in resource manager, or a custom resource manager loaded by an
27117 extension.
27118 </para></entry>
27119 </row>
27120 </tbody>
27121 </tgroup>
27122 </table>
27124 <para>
27125 The functions shown in <xref
27126 linkend="functions-recovery-control-table"/> control the progress of recovery.
27127 These functions may be executed only during recovery.
27128 </para>
27130 <table id="functions-recovery-control-table">
27131 <title>Recovery Control Functions</title>
27132 <tgroup cols="1">
27133 <thead>
27134 <row>
27135 <entry role="func_table_entry"><para role="func_signature">
27136 Function
27137 </para>
27138 <para>
27139 Description
27140 </para></entry>
27141 </row>
27142 </thead>
27144 <tbody>
27145 <row>
27146 <entry role="func_table_entry"><para role="func_signature">
27147 <indexterm>
27148 <primary>pg_is_wal_replay_paused</primary>
27149 </indexterm>
27150 <function>pg_is_wal_replay_paused</function> ()
27151 <returnvalue>boolean</returnvalue>
27152 </para>
27153 <para>
27154 Returns true if recovery pause is requested.
27155 </para></entry>
27156 </row>
27158 <row>
27159 <entry role="func_table_entry"><para role="func_signature">
27160 <indexterm>
27161 <primary>pg_get_wal_replay_pause_state</primary>
27162 </indexterm>
27163 <function>pg_get_wal_replay_pause_state</function> ()
27164 <returnvalue>text</returnvalue>
27165 </para>
27166 <para>
27167 Returns recovery pause state. The return values are <literal>
27168 not paused</literal> if pause is not requested, <literal>
27169 pause requested</literal> if pause is requested but recovery is
27170 not yet paused, and <literal>paused</literal> if the recovery is
27171 actually paused.
27172 </para></entry>
27173 </row>
27175 <row>
27176 <entry role="func_table_entry"><para role="func_signature">
27177 <indexterm>
27178 <primary>pg_promote</primary>
27179 </indexterm>
27180 <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> )
27181 <returnvalue>boolean</returnvalue>
27182 </para>
27183 <para>
27184 Promotes a standby server to primary status.
27185 With <parameter>wait</parameter> set to <literal>true</literal> (the
27186 default), the function waits until promotion is completed
27187 or <parameter>wait_seconds</parameter> seconds have passed, and
27188 returns <literal>true</literal> if promotion is successful
27189 and <literal>false</literal> otherwise.
27190 If <parameter>wait</parameter> is set to <literal>false</literal>, the
27191 function returns <literal>true</literal> immediately after sending a
27192 <literal>SIGUSR1</literal> signal to the postmaster to trigger
27193 promotion.
27194 </para>
27195 <para>
27196 This function is restricted to superusers by default, but other users
27197 can be granted EXECUTE to run the function.
27198 </para></entry>
27199 </row>
27201 <row>
27202 <entry role="func_table_entry"><para role="func_signature">
27203 <indexterm>
27204 <primary>pg_wal_replay_pause</primary>
27205 </indexterm>
27206 <function>pg_wal_replay_pause</function> ()
27207 <returnvalue>void</returnvalue>
27208 </para>
27209 <para>
27210 Request to pause recovery. A request doesn't mean that recovery stops
27211 right away. If you want a guarantee that recovery is actually paused,
27212 you need to check for the recovery pause state returned by
27213 <function>pg_get_wal_replay_pause_state()</function>. Note that
27214 <function>pg_is_wal_replay_paused()</function> returns whether a request
27215 is made. While recovery is paused, no further database changes are applied.
27216 If hot standby is active, all new queries will see the same consistent
27217 snapshot of the database, and no further query conflicts will be generated
27218 until recovery is resumed.
27219 </para>
27220 <para>
27221 This function is restricted to superusers by default, but other users
27222 can be granted EXECUTE to run the function.
27223 </para></entry>
27224 </row>
27226 <row>
27227 <entry role="func_table_entry"><para role="func_signature">
27228 <indexterm>
27229 <primary>pg_wal_replay_resume</primary>
27230 </indexterm>
27231 <function>pg_wal_replay_resume</function> ()
27232 <returnvalue>void</returnvalue>
27233 </para>
27234 <para>
27235 Restarts recovery if it was paused.
27236 </para>
27237 <para>
27238 This function is restricted to superusers by default, but other users
27239 can be granted EXECUTE to run the function.
27240 </para></entry>
27241 </row>
27242 </tbody>
27243 </tgroup>
27244 </table>
27246 <para>
27247 <function>pg_wal_replay_pause</function> and
27248 <function>pg_wal_replay_resume</function> cannot be executed while
27249 a promotion is ongoing. If a promotion is triggered while recovery
27250 is paused, the paused state ends and promotion continues.
27251 </para>
27253 <para>
27254 If streaming replication is disabled, the paused state may continue
27255 indefinitely without a problem. If streaming replication is in
27256 progress then WAL records will continue to be received, which will
27257 eventually fill available disk space, depending upon the duration of
27258 the pause, the rate of WAL generation and available disk space.
27259 </para>
27261 </sect2>
27263 <sect2 id="functions-snapshot-synchronization">
27264 <title>Snapshot Synchronization Functions</title>
27266 <para>
27267 <productname>PostgreSQL</productname> allows database sessions to synchronize their
27268 snapshots. A <firstterm>snapshot</firstterm> determines which data is visible to the
27269 transaction that is using the snapshot. Synchronized snapshots are
27270 necessary when two or more sessions need to see identical content in the
27271 database. If two sessions just start their transactions independently,
27272 there is always a possibility that some third transaction commits
27273 between the executions of the two <command>START TRANSACTION</command> commands,
27274 so that one session sees the effects of that transaction and the other
27275 does not.
27276 </para>
27278 <para>
27279 To solve this problem, <productname>PostgreSQL</productname> allows a transaction to
27280 <firstterm>export</firstterm> the snapshot it is using. As long as the exporting
27281 transaction remains open, other transactions can <firstterm>import</firstterm> its
27282 snapshot, and thereby be guaranteed that they see exactly the same view
27283 of the database that the first transaction sees. But note that any
27284 database changes made by any one of these transactions remain invisible
27285 to the other transactions, as is usual for changes made by uncommitted
27286 transactions. So the transactions are synchronized with respect to
27287 pre-existing data, but act normally for changes they make themselves.
27288 </para>
27290 <para>
27291 Snapshots are exported with the <function>pg_export_snapshot</function> function,
27292 shown in <xref linkend="functions-snapshot-synchronization-table"/>, and
27293 imported with the <xref linkend="sql-set-transaction"/> command.
27294 </para>
27296 <table id="functions-snapshot-synchronization-table">
27297 <title>Snapshot Synchronization Functions</title>
27298 <tgroup cols="1">
27299 <thead>
27300 <row>
27301 <entry role="func_table_entry"><para role="func_signature">
27302 Function
27303 </para>
27304 <para>
27305 Description
27306 </para></entry>
27307 </row>
27308 </thead>
27310 <tbody>
27311 <row>
27312 <entry role="func_table_entry"><para role="func_signature">
27313 <indexterm>
27314 <primary>pg_export_snapshot</primary>
27315 </indexterm>
27316 <function>pg_export_snapshot</function> ()
27317 <returnvalue>text</returnvalue>
27318 </para>
27319 <para>
27320 Saves the transaction's current snapshot and returns
27321 a <type>text</type> string identifying the snapshot. This string must
27322 be passed (outside the database) to clients that want to import the
27323 snapshot. The snapshot is available for import only until the end of
27324 the transaction that exported it.
27325 </para>
27326 <para>
27327 A transaction can export more than one snapshot, if needed. Note that
27328 doing so is only useful in <literal>READ COMMITTED</literal>
27329 transactions, since in <literal>REPEATABLE READ</literal> and higher
27330 isolation levels, transactions use the same snapshot throughout their
27331 lifetime. Once a transaction has exported any snapshots, it cannot be
27332 prepared with <xref linkend="sql-prepare-transaction"/>.
27333 </para></entry>
27334 </row>
27335 </tbody>
27336 </tgroup>
27337 </table>
27339 </sect2>
27341 <sect2 id="functions-replication">
27342 <title>Replication Management Functions</title>
27344 <para>
27345 The functions shown
27346 in <xref linkend="functions-replication-table"/> are for
27347 controlling and interacting with replication features.
27348 See <xref linkend="streaming-replication"/>,
27349 <xref linkend="streaming-replication-slots"/>, and
27350 <xref linkend="replication-origins"/>
27351 for information about the underlying features.
27352 Use of functions for replication origin is only allowed to the
27353 superuser by default, but may be allowed to other users by using the
27354 <literal>GRANT</literal> command.
27355 Use of functions for replication slots is restricted to superusers
27356 and users having <literal>REPLICATION</literal> privilege.
27357 </para>
27359 <para>
27360 Many of these functions have equivalent commands in the replication
27361 protocol; see <xref linkend="protocol-replication"/>.
27362 </para>
27364 <para>
27365 The functions described in
27366 <xref linkend="functions-admin-backup"/>,
27367 <xref linkend="functions-recovery-control"/>, and
27368 <xref linkend="functions-snapshot-synchronization"/>
27369 are also relevant for replication.
27370 </para>
27372 <table id="functions-replication-table">
27373 <title>Replication Management Functions</title>
27374 <tgroup cols="1">
27375 <thead>
27376 <row>
27377 <entry role="func_table_entry"><para role="func_signature">
27378 Function
27379 </para>
27380 <para>
27381 Description
27382 </para></entry>
27383 </row>
27384 </thead>
27386 <tbody>
27387 <row>
27388 <entry role="func_table_entry"><para role="func_signature">
27389 <indexterm>
27390 <primary>pg_create_physical_replication_slot</primary>
27391 </indexterm>
27392 <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> )
27393 <returnvalue>record</returnvalue>
27394 ( <parameter>slot_name</parameter> <type>name</type>,
27395 <parameter>lsn</parameter> <type>pg_lsn</type> )
27396 </para>
27397 <para>
27398 Creates a new physical replication slot named
27399 <parameter>slot_name</parameter>. The optional second parameter,
27400 when <literal>true</literal>, specifies that the <acronym>LSN</acronym> for this
27401 replication slot be reserved immediately; otherwise
27402 the <acronym>LSN</acronym> is reserved on first connection from a streaming
27403 replication client. Streaming changes from a physical slot is only
27404 possible with the streaming-replication protocol &mdash;
27405 see <xref linkend="protocol-replication"/>. The optional third
27406 parameter, <parameter>temporary</parameter>, when set to true, specifies that
27407 the slot should not be permanently stored to disk and is only meant
27408 for use by the current session. Temporary slots are also
27409 released upon any error. This function corresponds
27410 to the replication protocol command <literal>CREATE_REPLICATION_SLOT
27411 ... PHYSICAL</literal>.
27412 </para></entry>
27413 </row>
27415 <row>
27416 <entry role="func_table_entry"><para role="func_signature">
27417 <indexterm>
27418 <primary>pg_drop_replication_slot</primary>
27419 </indexterm>
27420 <function>pg_drop_replication_slot</function> ( <parameter>slot_name</parameter> <type>name</type> )
27421 <returnvalue>void</returnvalue>
27422 </para>
27423 <para>
27424 Drops the physical or logical replication slot
27425 named <parameter>slot_name</parameter>. Same as replication protocol
27426 command <literal>DROP_REPLICATION_SLOT</literal>. For logical slots, this must
27427 be called while connected to the same database the slot was created on.
27428 </para></entry>
27429 </row>
27431 <row>
27432 <entry role="func_table_entry"><para role="func_signature">
27433 <indexterm>
27434 <primary>pg_create_logical_replication_slot</primary>
27435 </indexterm>
27436 <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>two_phase</parameter> <type>boolean</type> </optional> )
27437 <returnvalue>record</returnvalue>
27438 ( <parameter>slot_name</parameter> <type>name</type>,
27439 <parameter>lsn</parameter> <type>pg_lsn</type> )
27440 </para>
27441 <para>
27442 Creates a new logical (decoding) replication slot named
27443 <parameter>slot_name</parameter> using the output plugin
27444 <parameter>plugin</parameter>. The optional third
27445 parameter, <parameter>temporary</parameter>, when set to true, specifies that
27446 the slot should not be permanently stored to disk and is only meant
27447 for use by the current session. Temporary slots are also
27448 released upon any error. The optional fourth parameter,
27449 <parameter>two_phase</parameter>, when set to true, specifies
27450 that the decoding of prepared transactions is enabled for this
27451 slot. A call to this function has the same effect as the replication
27452 protocol command <literal>CREATE_REPLICATION_SLOT ... LOGICAL</literal>.
27453 </para></entry>
27454 </row>
27456 <row>
27457 <entry role="func_table_entry"><para role="func_signature">
27458 <indexterm>
27459 <primary>pg_copy_physical_replication_slot</primary>
27460 </indexterm>
27461 <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> )
27462 <returnvalue>record</returnvalue>
27463 ( <parameter>slot_name</parameter> <type>name</type>,
27464 <parameter>lsn</parameter> <type>pg_lsn</type> )
27465 </para>
27466 <para>
27467 Copies an existing physical replication slot named <parameter>src_slot_name</parameter>
27468 to a physical replication slot named <parameter>dst_slot_name</parameter>.
27469 The copied physical slot starts to reserve WAL from the same <acronym>LSN</acronym> as the
27470 source slot.
27471 <parameter>temporary</parameter> is optional. If <parameter>temporary</parameter>
27472 is omitted, the same value as the source slot is used.
27473 </para></entry>
27474 </row>
27476 <row>
27477 <entry role="func_table_entry"><para role="func_signature">
27478 <indexterm>
27479 <primary>pg_copy_logical_replication_slot</primary>
27480 </indexterm>
27481 <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> )
27482 <returnvalue>record</returnvalue>
27483 ( <parameter>slot_name</parameter> <type>name</type>,
27484 <parameter>lsn</parameter> <type>pg_lsn</type> )
27485 </para>
27486 <para>
27487 Copies an existing logical replication slot
27488 named <parameter>src_slot_name</parameter> to a logical replication
27489 slot named <parameter>dst_slot_name</parameter>, optionally changing
27490 the output plugin and persistence. The copied logical slot starts
27491 from the same <acronym>LSN</acronym> as the source logical slot. Both
27492 <parameter>temporary</parameter> and <parameter>plugin</parameter> are
27493 optional; if they are omitted, the values of the source slot are used.
27494 </para></entry>
27495 </row>
27497 <row>
27498 <entry role="func_table_entry"><para role="func_signature">
27499 <indexterm>
27500 <primary>pg_logical_slot_get_changes</primary>
27501 </indexterm>
27502 <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> )
27503 <returnvalue>setof record</returnvalue>
27504 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27505 <parameter>xid</parameter> <type>xid</type>,
27506 <parameter>data</parameter> <type>text</type> )
27507 </para>
27508 <para>
27509 Returns changes in the slot <parameter>slot_name</parameter>, starting
27510 from the point from which changes have been consumed last. If
27511 <parameter>upto_lsn</parameter>
27512 and <parameter>upto_nchanges</parameter> are NULL,
27513 logical decoding will continue until end of WAL. If
27514 <parameter>upto_lsn</parameter> is non-NULL, decoding will include only
27515 those transactions which commit prior to the specified LSN. If
27516 <parameter>upto_nchanges</parameter> is non-NULL, decoding will
27517 stop when the number of rows produced by decoding exceeds
27518 the specified value. Note, however, that the actual number of
27519 rows returned may be larger, since this limit is only checked after
27520 adding the rows produced when decoding each new transaction commit.
27521 </para></entry>
27522 </row>
27524 <row>
27525 <entry role="func_table_entry"><para role="func_signature">
27526 <indexterm>
27527 <primary>pg_logical_slot_peek_changes</primary>
27528 </indexterm>
27529 <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> )
27530 <returnvalue>setof record</returnvalue>
27531 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27532 <parameter>xid</parameter> <type>xid</type>,
27533 <parameter>data</parameter> <type>text</type> )
27534 </para>
27535 <para>
27536 Behaves just like
27537 the <function>pg_logical_slot_get_changes()</function> function,
27538 except that changes are not consumed; that is, they will be returned
27539 again on future calls.
27540 </para></entry>
27541 </row>
27543 <row>
27544 <entry role="func_table_entry"><para role="func_signature">
27545 <indexterm>
27546 <primary>pg_logical_slot_get_binary_changes</primary>
27547 </indexterm>
27548 <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> )
27549 <returnvalue>setof record</returnvalue>
27550 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27551 <parameter>xid</parameter> <type>xid</type>,
27552 <parameter>data</parameter> <type>bytea</type> )
27553 </para>
27554 <para>
27555 Behaves just like
27556 the <function>pg_logical_slot_get_changes()</function> function,
27557 except that changes are returned as <type>bytea</type>.
27558 </para></entry>
27559 </row>
27561 <row>
27562 <entry role="func_table_entry"><para role="func_signature">
27563 <indexterm>
27564 <primary>pg_logical_slot_peek_binary_changes</primary>
27565 </indexterm>
27566 <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> )
27567 <returnvalue>setof record</returnvalue>
27568 ( <parameter>lsn</parameter> <type>pg_lsn</type>,
27569 <parameter>xid</parameter> <type>xid</type>,
27570 <parameter>data</parameter> <type>bytea</type> )
27571 </para>
27572 <para>
27573 Behaves just like
27574 the <function>pg_logical_slot_peek_changes()</function> function,
27575 except that changes are returned as <type>bytea</type>.
27576 </para></entry>
27577 </row>
27579 <row>
27580 <entry role="func_table_entry"><para role="func_signature">
27581 <indexterm>
27582 <primary>pg_replication_slot_advance</primary>
27583 </indexterm>
27584 <function>pg_replication_slot_advance</function> ( <parameter>slot_name</parameter> <type>name</type>, <parameter>upto_lsn</parameter> <type>pg_lsn</type> )
27585 <returnvalue>record</returnvalue>
27586 ( <parameter>slot_name</parameter> <type>name</type>,
27587 <parameter>end_lsn</parameter> <type>pg_lsn</type> )
27588 </para>
27589 <para>
27590 Advances the current confirmed position of a replication slot named
27591 <parameter>slot_name</parameter>. The slot will not be moved backwards,
27592 and it will not be moved beyond the current insert location. Returns
27593 the name of the slot and the actual position that it was advanced to.
27594 The updated slot position information is written out at the next
27595 checkpoint if any advancing is done. So in the event of a crash, the
27596 slot may return to an earlier position.
27597 </para></entry>
27598 </row>
27600 <row>
27601 <entry id="pg-replication-origin-create" role="func_table_entry"><para role="func_signature">
27602 <indexterm>
27603 <primary>pg_replication_origin_create</primary>
27604 </indexterm>
27605 <function>pg_replication_origin_create</function> ( <parameter>node_name</parameter> <type>text</type> )
27606 <returnvalue>oid</returnvalue>
27607 </para>
27608 <para>
27609 Creates a replication origin with the given external
27610 name, and returns the internal ID assigned to it.
27611 </para></entry>
27612 </row>
27614 <row>
27615 <entry id="pg-replication-origin-drop" role="func_table_entry"><para role="func_signature">
27616 <indexterm>
27617 <primary>pg_replication_origin_drop</primary>
27618 </indexterm>
27619 <function>pg_replication_origin_drop</function> ( <parameter>node_name</parameter> <type>text</type> )
27620 <returnvalue>void</returnvalue>
27621 </para>
27622 <para>
27623 Deletes a previously-created replication origin, including any
27624 associated replay progress.
27625 </para></entry>
27626 </row>
27628 <row>
27629 <entry role="func_table_entry"><para role="func_signature">
27630 <indexterm>
27631 <primary>pg_replication_origin_oid</primary>
27632 </indexterm>
27633 <function>pg_replication_origin_oid</function> ( <parameter>node_name</parameter> <type>text</type> )
27634 <returnvalue>oid</returnvalue>
27635 </para>
27636 <para>
27637 Looks up a replication origin by name and returns the internal ID. If
27638 no such replication origin is found, <literal>NULL</literal> is
27639 returned.
27640 </para></entry>
27641 </row>
27643 <row>
27644 <entry id="pg-replication-origin-session-setup" role="func_table_entry"><para role="func_signature">
27645 <indexterm>
27646 <primary>pg_replication_origin_session_setup</primary>
27647 </indexterm>
27648 <function>pg_replication_origin_session_setup</function> ( <parameter>node_name</parameter> <type>text</type> )
27649 <returnvalue>void</returnvalue>
27650 </para>
27651 <para>
27652 Marks the current session as replaying from the given
27653 origin, allowing replay progress to be tracked.
27654 Can only be used if no origin is currently selected.
27655 Use <function>pg_replication_origin_session_reset</function> to undo.
27656 </para></entry>
27657 </row>
27659 <row>
27660 <entry role="func_table_entry"><para role="func_signature">
27661 <indexterm>
27662 <primary>pg_replication_origin_session_reset</primary>
27663 </indexterm>
27664 <function>pg_replication_origin_session_reset</function> ()
27665 <returnvalue>void</returnvalue>
27666 </para>
27667 <para>
27668 Cancels the effects
27669 of <function>pg_replication_origin_session_setup()</function>.
27670 </para></entry>
27671 </row>
27673 <row>
27674 <entry role="func_table_entry"><para role="func_signature">
27675 <indexterm>
27676 <primary>pg_replication_origin_session_is_setup</primary>
27677 </indexterm>
27678 <function>pg_replication_origin_session_is_setup</function> ()
27679 <returnvalue>boolean</returnvalue>
27680 </para>
27681 <para>
27682 Returns true if a replication origin has been selected in the
27683 current session.
27684 </para></entry>
27685 </row>
27687 <row>
27688 <entry id="pg-replication-origin-session-progress" role="func_table_entry"><para role="func_signature">
27689 <indexterm>
27690 <primary>pg_replication_origin_session_progress</primary>
27691 </indexterm>
27692 <function>pg_replication_origin_session_progress</function> ( <parameter>flush</parameter> <type>boolean</type> )
27693 <returnvalue>pg_lsn</returnvalue>
27694 </para>
27695 <para>
27696 Returns the replay location for the replication origin selected in
27697 the current session. The parameter <parameter>flush</parameter>
27698 determines whether the corresponding local transaction will be
27699 guaranteed to have been flushed to disk or not.
27700 </para></entry>
27701 </row>
27703 <row>
27704 <entry id="pg-replication-origin-xact-setup" role="func_table_entry"><para role="func_signature">
27705 <indexterm>
27706 <primary>pg_replication_origin_xact_setup</primary>
27707 </indexterm>
27708 <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> )
27709 <returnvalue>void</returnvalue>
27710 </para>
27711 <para>
27712 Marks the current transaction as replaying a transaction that has
27713 committed at the given <acronym>LSN</acronym> and timestamp. Can
27714 only be called when a replication origin has been selected
27715 using <function>pg_replication_origin_session_setup</function>.
27716 </para></entry>
27717 </row>
27719 <row>
27720 <entry id="pg-replication-origin-xact-reset" role="func_table_entry"><para role="func_signature">
27721 <indexterm>
27722 <primary>pg_replication_origin_xact_reset</primary>
27723 </indexterm>
27724 <function>pg_replication_origin_xact_reset</function> ()
27725 <returnvalue>void</returnvalue>
27726 </para>
27727 <para>
27728 Cancels the effects of
27729 <function>pg_replication_origin_xact_setup()</function>.
27730 </para></entry>
27731 </row>
27733 <row>
27734 <entry id="pg-replication-origin-advance" role="func_table_entry"><para role="func_signature">
27735 <indexterm>
27736 <primary>pg_replication_origin_advance</primary>
27737 </indexterm>
27738 <function>pg_replication_origin_advance</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>lsn</parameter> <type>pg_lsn</type> )
27739 <returnvalue>void</returnvalue>
27740 </para>
27741 <para>
27742 Sets replication progress for the given node to the given
27743 location. This is primarily useful for setting up the initial
27744 location, or setting a new location after configuration changes and
27745 similar. Be aware that careless use of this function can lead to
27746 inconsistently replicated data.
27747 </para></entry>
27748 </row>
27750 <row>
27751 <entry id="pg-replication-origin-progress" role="func_table_entry"><para role="func_signature">
27752 <indexterm>
27753 <primary>pg_replication_origin_progress</primary>
27754 </indexterm>
27755 <function>pg_replication_origin_progress</function> ( <parameter>node_name</parameter> <type>text</type>, <parameter>flush</parameter> <type>boolean</type> )
27756 <returnvalue>pg_lsn</returnvalue>
27757 </para>
27758 <para>
27759 Returns the replay location for the given replication origin. The
27760 parameter <parameter>flush</parameter> determines whether the
27761 corresponding local transaction will be guaranteed to have been
27762 flushed to disk or not.
27763 </para></entry>
27764 </row>
27766 <row>
27767 <entry id="pg-logical-emit-message" role="func_table_entry"><para role="func_signature">
27768 <indexterm>
27769 <primary>pg_logical_emit_message</primary>
27770 </indexterm>
27771 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>text</type> )
27772 <returnvalue>pg_lsn</returnvalue>
27773 </para>
27774 <para role="func_signature">
27775 <function>pg_logical_emit_message</function> ( <parameter>transactional</parameter> <type>boolean</type>, <parameter>prefix</parameter> <type>text</type>, <parameter>content</parameter> <type>bytea</type> )
27776 <returnvalue>pg_lsn</returnvalue>
27777 </para>
27778 <para>
27779 Emits a logical decoding message. This can be used to pass generic
27780 messages to logical decoding plugins through
27781 WAL. The <parameter>transactional</parameter> parameter specifies if
27782 the message should be part of the current transaction, or if it should
27783 be written immediately and decoded as soon as the logical decoder
27784 reads the record. The <parameter>prefix</parameter> parameter is a
27785 textual prefix that can be used by logical decoding plugins to easily
27786 recognize messages that are interesting for them.
27787 The <parameter>content</parameter> parameter is the content of the
27788 message, given either in text or binary form.
27789 </para></entry>
27790 </row>
27791 </tbody>
27792 </tgroup>
27793 </table>
27795 </sect2>
27797 <sect2 id="functions-admin-dbobject">
27798 <title>Database Object Management Functions</title>
27800 <para>
27801 The functions shown in <xref linkend="functions-admin-dbsize"/> calculate
27802 the disk space usage of database objects, or assist in presentation
27803 or understanding of usage results. <literal>bigint</literal> results
27804 are measured in bytes. If an OID that does
27805 not represent an existing object is passed to one of these
27806 functions, <literal>NULL</literal> is returned.
27807 </para>
27809 <table id="functions-admin-dbsize">
27810 <title>Database Object Size Functions</title>
27811 <tgroup cols="1">
27812 <thead>
27813 <row>
27814 <entry role="func_table_entry"><para role="func_signature">
27815 Function
27816 </para>
27817 <para>
27818 Description
27819 </para></entry>
27820 </row>
27821 </thead>
27823 <tbody>
27824 <row>
27825 <entry role="func_table_entry"><para role="func_signature">
27826 <indexterm>
27827 <primary>pg_column_size</primary>
27828 </indexterm>
27829 <function>pg_column_size</function> ( <type>"any"</type> )
27830 <returnvalue>integer</returnvalue>
27831 </para>
27832 <para>
27833 Shows the number of bytes used to store any individual data value. If
27834 applied directly to a table column value, this reflects any
27835 compression that was done.
27836 </para></entry>
27837 </row>
27839 <row>
27840 <entry role="func_table_entry"><para role="func_signature">
27841 <indexterm>
27842 <primary>pg_column_compression</primary>
27843 </indexterm>
27844 <function>pg_column_compression</function> ( <type>"any"</type> )
27845 <returnvalue>text</returnvalue>
27846 </para>
27847 <para>
27848 Shows the compression algorithm that was used to compress
27849 an individual variable-length value. Returns <literal>NULL</literal>
27850 if the value is not compressed.
27851 </para></entry>
27852 </row>
27854 <row>
27855 <entry role="func_table_entry"><para role="func_signature">
27856 <indexterm>
27857 <primary>pg_database_size</primary>
27858 </indexterm>
27859 <function>pg_database_size</function> ( <type>name</type> )
27860 <returnvalue>bigint</returnvalue>
27861 </para>
27862 <para role="func_signature">
27863 <function>pg_database_size</function> ( <type>oid</type> )
27864 <returnvalue>bigint</returnvalue>
27865 </para>
27866 <para>
27867 Computes the total disk space used by the database with the specified
27868 name or OID. To use this function, you must
27869 have <literal>CONNECT</literal> privilege on the specified database
27870 (which is granted by default) or have privileges of
27871 the <literal>pg_read_all_stats</literal> role.
27872 </para></entry>
27873 </row>
27875 <row>
27876 <entry role="func_table_entry"><para role="func_signature">
27877 <indexterm>
27878 <primary>pg_indexes_size</primary>
27879 </indexterm>
27880 <function>pg_indexes_size</function> ( <type>regclass</type> )
27881 <returnvalue>bigint</returnvalue>
27882 </para>
27883 <para>
27884 Computes the total disk space used by indexes attached to the
27885 specified table.
27886 </para></entry>
27887 </row>
27889 <row>
27890 <entry role="func_table_entry"><para role="func_signature">
27891 <indexterm>
27892 <primary>pg_relation_size</primary>
27893 </indexterm>
27894 <function>pg_relation_size</function> ( <parameter>relation</parameter> <type>regclass</type> <optional>, <parameter>fork</parameter> <type>text</type> </optional> )
27895 <returnvalue>bigint</returnvalue>
27896 </para>
27897 <para>
27898 Computes the disk space used by one <quote>fork</quote> of the
27899 specified relation. (Note that for most purposes it is more
27900 convenient to use the higher-level
27901 functions <function>pg_total_relation_size</function>
27902 or <function>pg_table_size</function>, which sum the sizes of all
27903 forks.) With one argument, this returns the size of the main data
27904 fork of the relation. The second argument can be provided to specify
27905 which fork to examine:
27906 <itemizedlist spacing="compact">
27907 <listitem>
27908 <para>
27909 <literal>main</literal> returns the size of the main
27910 data fork of the relation.
27911 </para>
27912 </listitem>
27913 <listitem>
27914 <para>
27915 <literal>fsm</literal> returns the size of the Free Space Map
27916 (see <xref linkend="storage-fsm"/>) associated with the relation.
27917 </para>
27918 </listitem>
27919 <listitem>
27920 <para>
27921 <literal>vm</literal> returns the size of the Visibility Map
27922 (see <xref linkend="storage-vm"/>) associated with the relation.
27923 </para>
27924 </listitem>
27925 <listitem>
27926 <para>
27927 <literal>init</literal> returns the size of the initialization
27928 fork, if any, associated with the relation.
27929 </para>
27930 </listitem>
27931 </itemizedlist>
27932 </para></entry>
27933 </row>
27935 <row>
27936 <entry role="func_table_entry"><para role="func_signature">
27937 <indexterm>
27938 <primary>pg_size_bytes</primary>
27939 </indexterm>
27940 <function>pg_size_bytes</function> ( <type>text</type> )
27941 <returnvalue>bigint</returnvalue>
27942 </para>
27943 <para>
27944 Converts a size in human-readable format (as returned
27945 by <function>pg_size_pretty</function>) into bytes.
27946 </para></entry>
27947 </row>
27949 <row>
27950 <entry role="func_table_entry"><para role="func_signature">
27951 <indexterm>
27952 <primary>pg_size_pretty</primary>
27953 </indexterm>
27954 <function>pg_size_pretty</function> ( <type>bigint</type> )
27955 <returnvalue>text</returnvalue>
27956 </para>
27957 <para role="func_signature">
27958 <function>pg_size_pretty</function> ( <type>numeric</type> )
27959 <returnvalue>text</returnvalue>
27960 </para>
27961 <para>
27962 Converts a size in bytes into a more easily human-readable format with
27963 size units (bytes, kB, MB, GB or TB as appropriate). Note that the
27964 units are powers of 2 rather than powers of 10, so 1kB is 1024 bytes,
27965 1MB is 1024<superscript>2</superscript> = 1048576 bytes, and so on.
27966 </para></entry>
27967 </row>
27969 <row>
27970 <entry role="func_table_entry"><para role="func_signature">
27971 <indexterm>
27972 <primary>pg_table_size</primary>
27973 </indexterm>
27974 <function>pg_table_size</function> ( <type>regclass</type> )
27975 <returnvalue>bigint</returnvalue>
27976 </para>
27977 <para>
27978 Computes the disk space used by the specified table, excluding indexes
27979 (but including its TOAST table if any, free space map, and visibility
27980 map).
27981 </para></entry>
27982 </row>
27984 <row>
27985 <entry role="func_table_entry"><para role="func_signature">
27986 <indexterm>
27987 <primary>pg_tablespace_size</primary>
27988 </indexterm>
27989 <function>pg_tablespace_size</function> ( <type>name</type> )
27990 <returnvalue>bigint</returnvalue>
27991 </para>
27992 <para role="func_signature">
27993 <function>pg_tablespace_size</function> ( <type>oid</type> )
27994 <returnvalue>bigint</returnvalue>
27995 </para>
27996 <para>
27997 Computes the total disk space used in the tablespace with the
27998 specified name or OID. To use this function, you must
27999 have <literal>CREATE</literal> privilege on the specified tablespace
28000 or have privileges of the <literal>pg_read_all_stats</literal> role,
28001 unless it is the default tablespace for the current database.
28002 </para></entry>
28003 </row>
28005 <row>
28006 <entry role="func_table_entry"><para role="func_signature">
28007 <indexterm>
28008 <primary>pg_total_relation_size</primary>
28009 </indexterm>
28010 <function>pg_total_relation_size</function> ( <type>regclass</type> )
28011 <returnvalue>bigint</returnvalue>
28012 </para>
28013 <para>
28014 Computes the total disk space used by the specified table, including
28015 all indexes and <acronym>TOAST</acronym> data. The result is
28016 equivalent to <function>pg_table_size</function>
28017 <literal>+</literal> <function>pg_indexes_size</function>.
28018 </para></entry>
28019 </row>
28020 </tbody>
28021 </tgroup>
28022 </table>
28024 <para>
28025 The functions above that operate on tables or indexes accept a
28026 <type>regclass</type> argument, which is simply the OID of the table or index
28027 in the <structname>pg_class</structname> system catalog. You do not have to look up
28028 the OID by hand, however, since the <type>regclass</type> data type's input
28029 converter will do the work for you. See <xref linkend="datatype-oid"/>
28030 for details.
28031 </para>
28033 <para>
28034 The functions shown in <xref linkend="functions-admin-dblocation"/> assist
28035 in identifying the specific disk files associated with database objects.
28036 </para>
28038 <table id="functions-admin-dblocation">
28039 <title>Database Object Location Functions</title>
28040 <tgroup cols="1">
28041 <thead>
28042 <row>
28043 <entry role="func_table_entry"><para role="func_signature">
28044 Function
28045 </para>
28046 <para>
28047 Description
28048 </para></entry>
28049 </row>
28050 </thead>
28052 <tbody>
28053 <row>
28054 <entry role="func_table_entry"><para role="func_signature">
28055 <indexterm>
28056 <primary>pg_relation_filenode</primary>
28057 </indexterm>
28058 <function>pg_relation_filenode</function> ( <parameter>relation</parameter> <type>regclass</type> )
28059 <returnvalue>oid</returnvalue>
28060 </para>
28061 <para>
28062 Returns the <quote>filenode</quote> number currently assigned to the
28063 specified relation. The filenode is the base component of the file
28064 name(s) used for the relation (see
28065 <xref linkend="storage-file-layout"/> for more information).
28066 For most relations the result is the same as
28067 <structname>pg_class</structname>.<structfield>relfilenode</structfield>,
28068 but for certain system catalogs <structfield>relfilenode</structfield>
28069 is zero and this function must be used to get the correct value. The
28070 function returns NULL if passed a relation that does not have storage,
28071 such as a view.
28072 </para></entry>
28073 </row>
28075 <row>
28076 <entry role="func_table_entry"><para role="func_signature">
28077 <indexterm>
28078 <primary>pg_relation_filepath</primary>
28079 </indexterm>
28080 <function>pg_relation_filepath</function> ( <parameter>relation</parameter> <type>regclass</type> )
28081 <returnvalue>text</returnvalue>
28082 </para>
28083 <para>
28084 Returns the entire file path name (relative to the database cluster's
28085 data directory, <varname>PGDATA</varname>) of the relation.
28086 </para></entry>
28087 </row>
28089 <row>
28090 <entry role="func_table_entry"><para role="func_signature">
28091 <indexterm>
28092 <primary>pg_filenode_relation</primary>
28093 </indexterm>
28094 <function>pg_filenode_relation</function> ( <parameter>tablespace</parameter> <type>oid</type>, <parameter>filenode</parameter> <type>oid</type> )
28095 <returnvalue>regclass</returnvalue>
28096 </para>
28097 <para>
28098 Returns a relation's OID given the tablespace OID and filenode it is
28099 stored under. This is essentially the inverse mapping of
28100 <function>pg_relation_filepath</function>. For a relation in the
28101 database's default tablespace, the tablespace can be specified as zero.
28102 Returns <literal>NULL</literal> if no relation in the current database
28103 is associated with the given values.
28104 </para></entry>
28105 </row>
28106 </tbody>
28107 </tgroup>
28108 </table>
28110 <para>
28111 <xref linkend="functions-admin-collation"/> lists functions used to manage
28112 collations.
28113 </para>
28115 <table id="functions-admin-collation">
28116 <title>Collation Management Functions</title>
28117 <tgroup cols="1">
28118 <thead>
28119 <row>
28120 <entry role="func_table_entry"><para role="func_signature">
28121 Function
28122 </para>
28123 <para>
28124 Description
28125 </para></entry>
28126 </row>
28127 </thead>
28129 <tbody>
28130 <row>
28131 <entry role="func_table_entry"><para role="func_signature">
28132 <indexterm>
28133 <primary>pg_collation_actual_version</primary>
28134 </indexterm>
28135 <function>pg_collation_actual_version</function> ( <type>oid</type> )
28136 <returnvalue>text</returnvalue>
28137 </para>
28138 <para>
28139 Returns the actual version of the collation object as it is currently
28140 installed in the operating system. If this is different from the
28141 value in
28142 <structname>pg_collation</structname>.<structfield>collversion</structfield>,
28143 then objects depending on the collation might need to be rebuilt. See
28144 also <xref linkend="sql-altercollation"/>.
28145 </para></entry>
28146 </row>
28148 <row>
28149 <entry role="func_table_entry"><para role="func_signature">
28150 <indexterm>
28151 <primary>pg_database_collation_actual_version</primary>
28152 </indexterm>
28153 <function>pg_database_collation_actual_version</function> ( <type>oid</type> )
28154 <returnvalue>text</returnvalue>
28155 </para>
28156 <para>
28157 Returns the actual version of the database's collation as it is currently
28158 installed in the operating system. If this is different from the
28159 value in
28160 <structname>pg_database</structname>.<structfield>datcollversion</structfield>,
28161 then objects depending on the collation might need to be rebuilt. See
28162 also <xref linkend="sql-alterdatabase"/>.
28163 </para></entry>
28164 </row>
28166 <row>
28167 <entry role="func_table_entry"><para role="func_signature">
28168 <indexterm>
28169 <primary>pg_import_system_collations</primary>
28170 </indexterm>
28171 <function>pg_import_system_collations</function> ( <parameter>schema</parameter> <type>regnamespace</type> )
28172 <returnvalue>integer</returnvalue>
28173 </para>
28174 <para>
28175 Adds collations to the system
28176 catalog <structname>pg_collation</structname> based on all the locales
28177 it finds in the operating system. This is
28178 what <command>initdb</command> uses; see
28179 <xref linkend="collation-managing"/> for more details. If additional
28180 locales are installed into the operating system later on, this
28181 function can be run again to add collations for the new locales.
28182 Locales that match existing entries
28183 in <structname>pg_collation</structname> will be skipped. (But
28184 collation objects based on locales that are no longer present in the
28185 operating system are not removed by this function.)
28186 The <parameter>schema</parameter> parameter would typically
28187 be <literal>pg_catalog</literal>, but that is not a requirement; the
28188 collations could be installed into some other schema as well. The
28189 function returns the number of new collation objects it created.
28190 Use of this function is restricted to superusers.
28191 </para></entry>
28192 </row>
28193 </tbody>
28194 </tgroup>
28195 </table>
28197 <para>
28198 <xref linkend="functions-info-partition"/> lists functions that provide
28199 information about the structure of partitioned tables.
28200 </para>
28202 <table id="functions-info-partition">
28203 <title>Partitioning Information Functions</title>
28204 <tgroup cols="1">
28205 <thead>
28206 <row>
28207 <entry role="func_table_entry"><para role="func_signature">
28208 Function
28209 </para>
28210 <para>
28211 Description
28212 </para></entry>
28213 </row>
28214 </thead>
28216 <tbody>
28217 <row>
28218 <entry role="func_table_entry"><para role="func_signature">
28219 <indexterm>
28220 <primary>pg_partition_tree</primary>
28221 </indexterm>
28222 <function>pg_partition_tree</function> ( <type>regclass</type> )
28223 <returnvalue>setof record</returnvalue>
28224 ( <parameter>relid</parameter> <type>regclass</type>,
28225 <parameter>parentrelid</parameter> <type>regclass</type>,
28226 <parameter>isleaf</parameter> <type>boolean</type>,
28227 <parameter>level</parameter> <type>integer</type> )
28228 </para>
28229 <para>
28230 Lists the tables or indexes in the partition tree of the
28231 given partitioned table or partitioned index, with one row for each
28232 partition. Information provided includes the OID of the partition,
28233 the OID of its immediate parent, a boolean value telling if the
28234 partition is a leaf, and an integer telling its level in the hierarchy.
28235 The level value is 0 for the input table or index, 1 for its
28236 immediate child partitions, 2 for their partitions, and so on.
28237 Returns no rows if the relation does not exist or is not a partition
28238 or partitioned table.
28239 </para></entry>
28240 </row>
28242 <row>
28243 <entry role="func_table_entry"><para role="func_signature">
28244 <indexterm>
28245 <primary>pg_partition_ancestors</primary>
28246 </indexterm>
28247 <function>pg_partition_ancestors</function> ( <type>regclass</type> )
28248 <returnvalue>setof regclass</returnvalue>
28249 </para>
28250 <para>
28251 Lists the ancestor relations of the given partition,
28252 including the relation itself. Returns no rows if the relation
28253 does not exist or is not a partition or partitioned table.
28254 </para></entry>
28255 </row>
28257 <row>
28258 <entry role="func_table_entry"><para role="func_signature">
28259 <indexterm>
28260 <primary>pg_partition_root</primary>
28261 </indexterm>
28262 <function>pg_partition_root</function> ( <type>regclass</type> )
28263 <returnvalue>regclass</returnvalue>
28264 </para>
28265 <para>
28266 Returns the top-most parent of the partition tree to which the given
28267 relation belongs. Returns <literal>NULL</literal> if the relation
28268 does not exist or is not a partition or partitioned table.
28269 </para></entry>
28270 </row>
28271 </tbody>
28272 </tgroup>
28273 </table>
28275 <para>
28276 For example, to check the total size of the data contained in a
28277 partitioned table <structname>measurement</structname>, one could use the
28278 following query:
28279 <programlisting>
28280 SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
28281 FROM pg_partition_tree('measurement');
28282 </programlisting>
28283 </para>
28285 </sect2>
28287 <sect2 id="functions-admin-index">
28288 <title>Index Maintenance Functions</title>
28290 <para>
28291 <xref linkend="functions-admin-index-table"/> shows the functions
28292 available for index maintenance tasks. (Note that these maintenance
28293 tasks are normally done automatically by autovacuum; use of these
28294 functions is only required in special cases.)
28295 These functions cannot be executed during recovery.
28296 Use of these functions is restricted to superusers and the owner
28297 of the given index.
28298 </para>
28300 <table id="functions-admin-index-table">
28301 <title>Index Maintenance Functions</title>
28302 <tgroup cols="1">
28303 <thead>
28304 <row>
28305 <entry role="func_table_entry"><para role="func_signature">
28306 Function
28307 </para>
28308 <para>
28309 Description
28310 </para></entry>
28311 </row>
28312 </thead>
28314 <tbody>
28315 <row>
28316 <entry role="func_table_entry"><para role="func_signature">
28317 <indexterm>
28318 <primary>brin_summarize_new_values</primary>
28319 </indexterm>
28320 <function>brin_summarize_new_values</function> ( <parameter>index</parameter> <type>regclass</type> )
28321 <returnvalue>integer</returnvalue>
28322 </para>
28323 <para>
28324 Scans the specified BRIN index to find page ranges in the base table
28325 that are not currently summarized by the index; for any such range it
28326 creates a new summary index tuple by scanning those table pages.
28327 Returns the number of new page range summaries that were inserted
28328 into the index.
28329 </para></entry>
28330 </row>
28332 <row>
28333 <entry role="func_table_entry"><para role="func_signature">
28334 <indexterm>
28335 <primary>brin_summarize_range</primary>
28336 </indexterm>
28337 <function>brin_summarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
28338 <returnvalue>integer</returnvalue>
28339 </para>
28340 <para>
28341 Summarizes the page range covering the given block, if not already
28342 summarized. This is
28343 like <function>brin_summarize_new_values</function> except that it
28344 only processes the page range that covers the given table block number.
28345 </para></entry>
28346 </row>
28348 <row>
28349 <entry role="func_table_entry"><para role="func_signature">
28350 <indexterm>
28351 <primary>brin_desummarize_range</primary>
28352 </indexterm>
28353 <function>brin_desummarize_range</function> ( <parameter>index</parameter> <type>regclass</type>, <parameter>blockNumber</parameter> <type>bigint</type> )
28354 <returnvalue>void</returnvalue>
28355 </para>
28356 <para>
28357 Removes the BRIN index tuple that summarizes the page range covering
28358 the given table block, if there is one.
28359 </para></entry>
28360 </row>
28362 <row>
28363 <entry role="func_table_entry"><para role="func_signature">
28364 <indexterm>
28365 <primary>gin_clean_pending_list</primary>
28366 </indexterm>
28367 <function>gin_clean_pending_list</function> ( <parameter>index</parameter> <type>regclass</type> )
28368 <returnvalue>bigint</returnvalue>
28369 </para>
28370 <para>
28371 Cleans up the <quote>pending</quote> list of the specified GIN index
28372 by moving entries in it, in bulk, to the main GIN data structure.
28373 Returns the number of pages removed from the pending list.
28374 If the argument is a GIN index built with
28375 the <literal>fastupdate</literal> option disabled, no cleanup happens
28376 and the result is zero, because the index doesn't have a pending list.
28377 See <xref linkend="gin-fast-update"/> and <xref linkend="gin-tips"/>
28378 for details about the pending list and <literal>fastupdate</literal>
28379 option.
28380 </para></entry>
28381 </row>
28382 </tbody>
28383 </tgroup>
28384 </table>
28386 </sect2>
28388 <sect2 id="functions-admin-genfile">
28389 <title>Generic File Access Functions</title>
28391 <para>
28392 The functions shown in <xref
28393 linkend="functions-admin-genfile-table"/> provide native access to
28394 files on the machine hosting the server. Only files within the
28395 database cluster directory and the <varname>log_directory</varname> can be
28396 accessed, unless the user is a superuser or is granted the role
28397 <literal>pg_read_server_files</literal>. Use a relative path for files in
28398 the cluster directory, and a path matching the <varname>log_directory</varname>
28399 configuration setting for log files.
28400 </para>
28402 <para>
28403 Note that granting users the EXECUTE privilege on
28404 <function>pg_read_file()</function>, or related functions, allows them the
28405 ability to read any file on the server that the database server process can
28406 read; these functions bypass all in-database privilege checks. This means
28407 that, for example, a user with such access is able to read the contents of
28408 the <structname>pg_authid</structname> table where authentication
28409 information is stored, as well as read any table data in the database.
28410 Therefore, granting access to these functions should be carefully
28411 considered.
28412 </para>
28414 <para>
28415 When granting privilege on these functions, note that the table entries
28416 showing optional parameters are mostly implemented as several physical
28417 functions with different parameter lists. Privilege must be granted
28418 separately on each such function, if it is to be
28419 used. <application>psql</application>'s <command>\df</command> command
28420 can be useful to check what the actual function signatures are.
28421 </para>
28423 <para>
28424 Some of these functions take an optional <parameter>missing_ok</parameter>
28425 parameter, which specifies the behavior when the file or directory does
28426 not exist. If <literal>true</literal>, the function
28427 returns <literal>NULL</literal> or an empty result set, as appropriate.
28428 If <literal>false</literal>, an error is raised. (Failure conditions
28429 other than <quote>file not found</quote> are reported as errors in any
28430 case.) The default is <literal>false</literal>.
28431 </para>
28433 <table id="functions-admin-genfile-table">
28434 <title>Generic File Access Functions</title>
28435 <tgroup cols="1">
28436 <thead>
28437 <row>
28438 <entry role="func_table_entry"><para role="func_signature">
28439 Function
28440 </para>
28441 <para>
28442 Description
28443 </para></entry>
28444 </row>
28445 </thead>
28447 <tbody>
28448 <row>
28449 <entry role="func_table_entry"><para role="func_signature">
28450 <indexterm>
28451 <primary>pg_ls_dir</primary>
28452 </indexterm>
28453 <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> )
28454 <returnvalue>setof text</returnvalue>
28455 </para>
28456 <para>
28457 Returns the names of all files (and directories and other special
28458 files) in the specified
28459 directory. The <parameter>include_dot_dirs</parameter> parameter
28460 indicates whether <quote>.</quote> and <quote>..</quote> are to be
28461 included in the result set; the default is to exclude them. Including
28462 them can be useful when <parameter>missing_ok</parameter>
28463 is <literal>true</literal>, to distinguish an empty directory from a
28464 non-existent directory.
28465 </para>
28466 <para>
28467 This function is restricted to superusers by default, but other users
28468 can be granted EXECUTE to run the function.
28469 </para></entry>
28470 </row>
28472 <row>
28473 <entry role="func_table_entry"><para role="func_signature">
28474 <indexterm>
28475 <primary>pg_ls_logdir</primary>
28476 </indexterm>
28477 <function>pg_ls_logdir</function> ()
28478 <returnvalue>setof record</returnvalue>
28479 ( <parameter>name</parameter> <type>text</type>,
28480 <parameter>size</parameter> <type>bigint</type>,
28481 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28482 </para>
28483 <para>
28484 Returns the name, size, and last modification time (mtime) of each
28485 ordinary file in the server's log directory. Filenames beginning with
28486 a dot, directories, and other special files are excluded.
28487 </para>
28488 <para>
28489 This function is restricted to superusers and roles with privileges of
28490 the <literal>pg_monitor</literal> role by default, but other users can
28491 be granted EXECUTE to run the function.
28492 </para></entry>
28493 </row>
28495 <row>
28496 <entry role="func_table_entry"><para role="func_signature">
28497 <indexterm>
28498 <primary>pg_ls_waldir</primary>
28499 </indexterm>
28500 <function>pg_ls_waldir</function> ()
28501 <returnvalue>setof record</returnvalue>
28502 ( <parameter>name</parameter> <type>text</type>,
28503 <parameter>size</parameter> <type>bigint</type>,
28504 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28505 </para>
28506 <para>
28507 Returns the name, size, and last modification time (mtime) of each
28508 ordinary file in the server's write-ahead log (WAL) directory.
28509 Filenames beginning with a dot, directories, and other special files
28510 are excluded.
28511 </para>
28512 <para>
28513 This function is restricted to superusers and roles with privileges of
28514 the <literal>pg_monitor</literal> role by default, but other users can
28515 be granted EXECUTE to run the function.
28516 </para></entry>
28517 </row>
28519 <row>
28520 <entry role="func_table_entry"><para role="func_signature">
28521 <indexterm>
28522 <primary>pg_ls_logicalmapdir</primary>
28523 </indexterm>
28524 <function>pg_ls_logicalmapdir</function> ()
28525 <returnvalue>setof record</returnvalue>
28526 ( <parameter>name</parameter> <type>text</type>,
28527 <parameter>size</parameter> <type>bigint</type>,
28528 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28529 </para>
28530 <para>
28531 Returns the name, size, and last modification time (mtime) of each
28532 ordinary file in the server's <filename>pg_logical/mappings</filename>
28533 directory. Filenames beginning with a dot, directories, and other
28534 special files are excluded.
28535 </para>
28536 <para>
28537 This function is restricted to superusers and members of
28538 the <literal>pg_monitor</literal> role by default, but other users can
28539 be granted EXECUTE to run the function.
28540 </para></entry>
28541 </row>
28543 <row>
28544 <entry role="func_table_entry"><para role="func_signature">
28545 <indexterm>
28546 <primary>pg_ls_logicalsnapdir</primary>
28547 </indexterm>
28548 <function>pg_ls_logicalsnapdir</function> ()
28549 <returnvalue>setof record</returnvalue>
28550 ( <parameter>name</parameter> <type>text</type>,
28551 <parameter>size</parameter> <type>bigint</type>,
28552 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28553 </para>
28554 <para>
28555 Returns the name, size, and last modification time (mtime) of each
28556 ordinary file in the server's <filename>pg_logical/snapshots</filename>
28557 directory. Filenames beginning with a dot, directories, and other
28558 special files are excluded.
28559 </para>
28560 <para>
28561 This function is restricted to superusers and members of
28562 the <literal>pg_monitor</literal> role by default, but other users can
28563 be granted EXECUTE to run the function.
28564 </para></entry>
28565 </row>
28567 <row>
28568 <entry role="func_table_entry"><para role="func_signature">
28569 <indexterm>
28570 <primary>pg_ls_replslotdir</primary>
28571 </indexterm>
28572 <function>pg_ls_replslotdir</function> ( <parameter>slot_name</parameter> <type>text</type> )
28573 <returnvalue>setof record</returnvalue>
28574 ( <parameter>name</parameter> <type>text</type>,
28575 <parameter>size</parameter> <type>bigint</type>,
28576 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28577 </para>
28578 <para>
28579 Returns the name, size, and last modification time (mtime) of each
28580 ordinary file in the server's <filename>pg_replslot/slot_name</filename>
28581 directory, where <parameter>slot_name</parameter> is the name of the
28582 replication slot provided as input of the function. Filenames beginning
28583 with a dot, directories, and other special files are excluded.
28584 </para>
28585 <para>
28586 This function is restricted to superusers and members of
28587 the <literal>pg_monitor</literal> role by default, but other users can
28588 be granted EXECUTE to run the function.
28589 </para></entry>
28590 </row>
28592 <row>
28593 <entry role="func_table_entry"><para role="func_signature">
28594 <indexterm>
28595 <primary>pg_ls_archive_statusdir</primary>
28596 </indexterm>
28597 <function>pg_ls_archive_statusdir</function> ()
28598 <returnvalue>setof record</returnvalue>
28599 ( <parameter>name</parameter> <type>text</type>,
28600 <parameter>size</parameter> <type>bigint</type>,
28601 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28602 </para>
28603 <para>
28604 Returns the name, size, and last modification time (mtime) of each
28605 ordinary file in the server's WAL archive status directory
28606 (<filename>pg_wal/archive_status</filename>). Filenames beginning
28607 with a dot, directories, and other special files are excluded.
28608 </para>
28609 <para>
28610 This function is restricted to superusers and members of
28611 the <literal>pg_monitor</literal> role by default, but other users can
28612 be granted EXECUTE to run the function.
28613 </para></entry>
28614 </row>
28616 <row>
28617 <entry role="func_table_entry"><para role="func_signature">
28619 <indexterm>
28620 <primary>pg_ls_tmpdir</primary>
28621 </indexterm>
28622 <function>pg_ls_tmpdir</function> ( <optional> <parameter>tablespace</parameter> <type>oid</type> </optional> )
28623 <returnvalue>setof record</returnvalue>
28624 ( <parameter>name</parameter> <type>text</type>,
28625 <parameter>size</parameter> <type>bigint</type>,
28626 <parameter>modification</parameter> <type>timestamp with time zone</type> )
28627 </para>
28628 <para>
28629 Returns the name, size, and last modification time (mtime) of each
28630 ordinary file in the temporary file directory for the
28631 specified <parameter>tablespace</parameter>.
28632 If <parameter>tablespace</parameter> is not provided,
28633 the <literal>pg_default</literal> tablespace is examined. Filenames
28634 beginning with a dot, directories, and other special files are
28635 excluded.
28636 </para>
28637 <para>
28638 This function is restricted to superusers and members of
28639 the <literal>pg_monitor</literal> role by default, but other users can
28640 be granted EXECUTE to run the function.
28641 </para></entry>
28642 </row>
28644 <row>
28645 <entry role="func_table_entry"><para role="func_signature">
28646 <indexterm>
28647 <primary>pg_read_file</primary>
28648 </indexterm>
28649 <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> )
28650 <returnvalue>text</returnvalue>
28651 </para>
28652 <para>
28653 Returns all or part of a text file, starting at the
28654 given byte <parameter>offset</parameter>, returning at
28655 most <parameter>length</parameter> bytes (less if the end of file is
28656 reached first). If <parameter>offset</parameter> is negative, it is
28657 relative to the end of the file. If <parameter>offset</parameter>
28658 and <parameter>length</parameter> are omitted, the entire file is
28659 returned. The bytes read from the file are interpreted as a string in
28660 the database's encoding; an error is thrown if they are not valid in
28661 that encoding.
28662 </para>
28663 <para>
28664 This function is restricted to superusers by default, but other users
28665 can be granted EXECUTE to run the function.
28666 </para></entry>
28667 </row>
28669 <row>
28670 <entry role="func_table_entry"><para role="func_signature">
28671 <indexterm>
28672 <primary>pg_read_binary_file</primary>
28673 </indexterm>
28674 <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> )
28675 <returnvalue>bytea</returnvalue>
28676 </para>
28677 <para>
28678 Returns all or part of a file. This function is identical to
28679 <function>pg_read_file</function> except that it can read arbitrary
28680 binary data, returning the result as <type>bytea</type>
28681 not <type>text</type>; accordingly, no encoding checks are performed.
28682 </para>
28683 <para>
28684 This function is restricted to superusers by default, but other users
28685 can be granted EXECUTE to run the function.
28686 </para>
28687 <para>
28688 In combination with the <function>convert_from</function> function,
28689 this function can be used to read a text file in a specified encoding
28690 and convert to the database's encoding:
28691 <programlisting>
28692 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
28693 </programlisting>
28694 </para></entry>
28695 </row>
28697 <row>
28698 <entry role="func_table_entry"><para role="func_signature">
28699 <indexterm>
28700 <primary>pg_stat_file</primary>
28701 </indexterm>
28702 <function>pg_stat_file</function> ( <parameter>filename</parameter> <type>text</type> <optional>, <parameter>missing_ok</parameter> <type>boolean</type> </optional> )
28703 <returnvalue>record</returnvalue>
28704 ( <parameter>size</parameter> <type>bigint</type>,
28705 <parameter>access</parameter> <type>timestamp with time zone</type>,
28706 <parameter>modification</parameter> <type>timestamp with time zone</type>,
28707 <parameter>change</parameter> <type>timestamp with time zone</type>,
28708 <parameter>creation</parameter> <type>timestamp with time zone</type>,
28709 <parameter>isdir</parameter> <type>boolean</type> )
28710 </para>
28711 <para>
28712 Returns a record containing the file's size, last access time stamp,
28713 last modification time stamp, last file status change time stamp (Unix
28714 platforms only), file creation time stamp (Windows only), and a flag
28715 indicating if it is a directory.
28716 </para>
28717 <para>
28718 This function is restricted to superusers by default, but other users
28719 can be granted EXECUTE to run the function.
28720 </para></entry>
28721 </row>
28723 </tbody>
28724 </tgroup>
28725 </table>
28727 </sect2>
28729 <sect2 id="functions-advisory-locks">
28730 <title>Advisory Lock Functions</title>
28732 <para>
28733 The functions shown in <xref linkend="functions-advisory-locks-table"/>
28734 manage advisory locks. For details about proper use of these functions,
28735 see <xref linkend="advisory-locks"/>.
28736 </para>
28738 <para>
28739 All these functions are intended to be used to lock application-defined
28740 resources, which can be identified either by a single 64-bit key value or
28741 two 32-bit key values (note that these two key spaces do not overlap).
28742 If another session already holds a conflicting lock on the same resource
28743 identifier, the functions will either wait until the resource becomes
28744 available, or return a <literal>false</literal> result, as appropriate for
28745 the function.
28746 Locks can be either shared or exclusive: a shared lock does not conflict
28747 with other shared locks on the same resource, only with exclusive locks.
28748 Locks can be taken at session level (so that they are held until released
28749 or the session ends) or at transaction level (so that they are held until
28750 the current transaction ends; there is no provision for manual release).
28751 Multiple session-level lock requests stack, so that if the same resource
28752 identifier is locked three times there must then be three unlock requests
28753 to release the resource in advance of session end.
28754 </para>
28756 <table id="functions-advisory-locks-table">
28757 <title>Advisory Lock Functions</title>
28758 <tgroup cols="1">
28759 <thead>
28760 <row>
28761 <entry role="func_table_entry"><para role="func_signature">
28762 Function
28763 </para>
28764 <para>
28765 Description
28766 </para></entry>
28767 </row>
28768 </thead>
28770 <tbody>
28771 <row>
28772 <entry role="func_table_entry"><para role="func_signature">
28773 <indexterm>
28774 <primary>pg_advisory_lock</primary>
28775 </indexterm>
28776 <function>pg_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28777 <returnvalue>void</returnvalue>
28778 </para>
28779 <para role="func_signature">
28780 <function>pg_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28781 <returnvalue>void</returnvalue>
28782 </para>
28783 <para>
28784 Obtains an exclusive session-level advisory lock, waiting if necessary.
28785 </para></entry>
28786 </row>
28788 <row>
28789 <entry role="func_table_entry"><para role="func_signature">
28790 <indexterm>
28791 <primary>pg_advisory_lock_shared</primary>
28792 </indexterm>
28793 <function>pg_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28794 <returnvalue>void</returnvalue>
28795 </para>
28796 <para role="func_signature">
28797 <function>pg_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28798 <returnvalue>void</returnvalue>
28799 </para>
28800 <para>
28801 Obtains a shared session-level advisory lock, waiting if necessary.
28802 </para></entry>
28803 </row>
28805 <row>
28806 <entry role="func_table_entry"><para role="func_signature">
28807 <indexterm>
28808 <primary>pg_advisory_unlock</primary>
28809 </indexterm>
28810 <function>pg_advisory_unlock</function> ( <parameter>key</parameter> <type>bigint</type> )
28811 <returnvalue>boolean</returnvalue>
28812 </para>
28813 <para role="func_signature">
28814 <function>pg_advisory_unlock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28815 <returnvalue>boolean</returnvalue>
28816 </para>
28817 <para>
28818 Releases a previously-acquired exclusive session-level advisory lock.
28819 Returns <literal>true</literal> if the lock is successfully released.
28820 If the lock was not held, <literal>false</literal> is returned, and in
28821 addition, an SQL warning will be reported by the server.
28822 </para></entry>
28823 </row>
28825 <row>
28826 <entry role="func_table_entry"><para role="func_signature">
28827 <indexterm>
28828 <primary>pg_advisory_unlock_all</primary>
28829 </indexterm>
28830 <function>pg_advisory_unlock_all</function> ()
28831 <returnvalue>void</returnvalue>
28832 </para>
28833 <para>
28834 Releases all session-level advisory locks held by the current session.
28835 (This function is implicitly invoked at session end, even if the
28836 client disconnects ungracefully.)
28837 </para></entry>
28838 </row>
28840 <row>
28841 <entry role="func_table_entry"><para role="func_signature">
28842 <indexterm>
28843 <primary>pg_advisory_unlock_shared</primary>
28844 </indexterm>
28845 <function>pg_advisory_unlock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28846 <returnvalue>boolean</returnvalue>
28847 </para>
28848 <para role="func_signature">
28849 <function>pg_advisory_unlock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28850 <returnvalue>boolean</returnvalue>
28851 </para>
28852 <para>
28853 Releases a previously-acquired shared session-level advisory lock.
28854 Returns <literal>true</literal> if the lock is successfully released.
28855 If the lock was not held, <literal>false</literal> is returned, and in
28856 addition, an SQL warning will be reported by the server.
28857 </para></entry>
28858 </row>
28860 <row>
28861 <entry role="func_table_entry"><para role="func_signature">
28862 <indexterm>
28863 <primary>pg_advisory_xact_lock</primary>
28864 </indexterm>
28865 <function>pg_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28866 <returnvalue>void</returnvalue>
28867 </para>
28868 <para role="func_signature">
28869 <function>pg_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28870 <returnvalue>void</returnvalue>
28871 </para>
28872 <para>
28873 Obtains an exclusive transaction-level advisory lock, waiting if
28874 necessary.
28875 </para></entry>
28876 </row>
28878 <row>
28879 <entry role="func_table_entry"><para role="func_signature">
28880 <indexterm>
28881 <primary>pg_advisory_xact_lock_shared</primary>
28882 </indexterm>
28883 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28884 <returnvalue>void</returnvalue>
28885 </para>
28886 <para role="func_signature">
28887 <function>pg_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28888 <returnvalue>void</returnvalue>
28889 </para>
28890 <para>
28891 Obtains a shared transaction-level advisory lock, waiting if
28892 necessary.
28893 </para></entry>
28894 </row>
28896 <row>
28897 <entry role="func_table_entry"><para role="func_signature">
28898 <indexterm>
28899 <primary>pg_try_advisory_lock</primary>
28900 </indexterm>
28901 <function>pg_try_advisory_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28902 <returnvalue>boolean</returnvalue>
28903 </para>
28904 <para role="func_signature">
28905 <function>pg_try_advisory_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28906 <returnvalue>boolean</returnvalue>
28907 </para>
28908 <para>
28909 Obtains an exclusive session-level advisory lock if available.
28910 This will either obtain the lock immediately and
28911 return <literal>true</literal>, or return <literal>false</literal>
28912 without waiting if the lock cannot be acquired immediately.
28913 </para></entry>
28914 </row>
28916 <row>
28917 <entry role="func_table_entry"><para role="func_signature">
28918 <indexterm>
28919 <primary>pg_try_advisory_lock_shared</primary>
28920 </indexterm>
28921 <function>pg_try_advisory_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28922 <returnvalue>boolean</returnvalue>
28923 </para>
28924 <para role="func_signature">
28925 <function>pg_try_advisory_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28926 <returnvalue>boolean</returnvalue>
28927 </para>
28928 <para>
28929 Obtains a shared session-level advisory lock if available.
28930 This will either obtain the lock immediately and
28931 return <literal>true</literal>, or return <literal>false</literal>
28932 without waiting if the lock cannot be acquired immediately.
28933 </para></entry>
28934 </row>
28936 <row>
28937 <entry role="func_table_entry"><para role="func_signature">
28938 <indexterm>
28939 <primary>pg_try_advisory_xact_lock</primary>
28940 </indexterm>
28941 <function>pg_try_advisory_xact_lock</function> ( <parameter>key</parameter> <type>bigint</type> )
28942 <returnvalue>boolean</returnvalue>
28943 </para>
28944 <para role="func_signature">
28945 <function>pg_try_advisory_xact_lock</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28946 <returnvalue>boolean</returnvalue>
28947 </para>
28948 <para>
28949 Obtains an exclusive transaction-level advisory lock if available.
28950 This will either obtain the lock immediately and
28951 return <literal>true</literal>, or return <literal>false</literal>
28952 without waiting if the lock cannot be acquired immediately.
28953 </para></entry>
28954 </row>
28956 <row>
28957 <entry role="func_table_entry"><para role="func_signature">
28958 <indexterm>
28959 <primary>pg_try_advisory_xact_lock_shared</primary>
28960 </indexterm>
28961 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key</parameter> <type>bigint</type> )
28962 <returnvalue>boolean</returnvalue>
28963 </para>
28964 <para role="func_signature">
28965 <function>pg_try_advisory_xact_lock_shared</function> ( <parameter>key1</parameter> <type>integer</type>, <parameter>key2</parameter> <type>integer</type> )
28966 <returnvalue>boolean</returnvalue>
28967 </para>
28968 <para>
28969 Obtains a shared transaction-level advisory lock if available.
28970 This will either obtain the lock immediately and
28971 return <literal>true</literal>, or return <literal>false</literal>
28972 without waiting if the lock cannot be acquired immediately.
28973 </para></entry>
28974 </row>
28975 </tbody>
28976 </tgroup>
28977 </table>
28979 </sect2>
28981 </sect1>
28983 <sect1 id="functions-trigger">
28984 <title>Trigger Functions</title>
28986 <para>
28987 While many uses of triggers involve user-written trigger functions,
28988 <productname>PostgreSQL</productname> provides a few built-in trigger
28989 functions that can be used directly in user-defined triggers. These
28990 are summarized in <xref linkend="builtin-triggers-table"/>.
28991 (Additional built-in trigger functions exist, which implement foreign
28992 key constraints and deferred index constraints. Those are not documented
28993 here since users need not use them directly.)
28994 </para>
28996 <para>
28997 For more information about creating triggers, see
28998 <xref linkend="sql-createtrigger"/>.
28999 </para>
29001 <table id="builtin-triggers-table">
29002 <title>Built-In Trigger Functions</title>
29003 <tgroup cols="1">
29004 <thead>
29005 <row>
29006 <entry role="func_table_entry"><para role="func_signature">
29007 Function
29008 </para>
29009 <para>
29010 Description
29011 </para>
29012 <para>
29013 Example Usage
29014 </para></entry>
29015 </row>
29016 </thead>
29018 <tbody>
29019 <row>
29020 <entry role="func_table_entry"><para role="func_signature">
29021 <indexterm>
29022 <primary>suppress_redundant_updates_trigger</primary>
29023 </indexterm>
29024 <function>suppress_redundant_updates_trigger</function> ( )
29025 <returnvalue>trigger</returnvalue>
29026 </para>
29027 <para>
29028 Suppresses do-nothing update operations. See below for details.
29029 </para>
29030 <para>
29031 <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()</literal>
29032 </para></entry>
29033 </row>
29035 <row>
29036 <entry role="func_table_entry"><para role="func_signature">
29037 <indexterm>
29038 <primary>tsvector_update_trigger</primary>
29039 </indexterm>
29040 <function>tsvector_update_trigger</function> ( )
29041 <returnvalue>trigger</returnvalue>
29042 </para>
29043 <para>
29044 Automatically updates a <type>tsvector</type> column from associated
29045 plain-text document column(s). The text search configuration to use
29046 is specified by name as a trigger argument. See
29047 <xref linkend="textsearch-update-triggers"/> for details.
29048 </para>
29049 <para>
29050 <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal>
29051 </para></entry>
29052 </row>
29054 <row>
29055 <entry role="func_table_entry"><para role="func_signature">
29056 <indexterm>
29057 <primary>tsvector_update_trigger_column</primary>
29058 </indexterm>
29059 <function>tsvector_update_trigger_column</function> ( )
29060 <returnvalue>trigger</returnvalue>
29061 </para>
29062 <para>
29063 Automatically updates a <type>tsvector</type> column from associated
29064 plain-text document column(s). The text search configuration to use
29065 is taken from a <type>regconfig</type> column of the table. See
29066 <xref linkend="textsearch-update-triggers"/> for details.
29067 </para>
29068 <para>
29069 <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)</literal>
29070 </para></entry>
29071 </row>
29072 </tbody>
29073 </tgroup>
29074 </table>
29076 <para>
29077 The <function>suppress_redundant_updates_trigger</function> function,
29078 when applied as a row-level <literal>BEFORE UPDATE</literal> trigger,
29079 will prevent any update that does not actually change the data in the
29080 row from taking place. This overrides the normal behavior which always
29081 performs a physical row update
29082 regardless of whether or not the data has changed. (This normal behavior
29083 makes updates run faster, since no checking is required, and is also
29084 useful in certain cases.)
29085 </para>
29087 <para>
29088 Ideally, you should avoid running updates that don't actually
29089 change the data in the record. Redundant updates can cost considerable
29090 unnecessary time, especially if there are lots of indexes to alter,
29091 and space in dead rows that will eventually have to be vacuumed.
29092 However, detecting such situations in client code is not
29093 always easy, or even possible, and writing expressions to detect
29094 them can be error-prone. An alternative is to use
29095 <function>suppress_redundant_updates_trigger</function>, which will skip
29096 updates that don't change the data. You should use this with care,
29097 however. The trigger takes a small but non-trivial time for each record,
29098 so if most of the records affected by updates do actually change,
29099 use of this trigger will make updates run slower on average.
29100 </para>
29102 <para>
29103 The <function>suppress_redundant_updates_trigger</function> function can be
29104 added to a table like this:
29105 <programlisting>
29106 CREATE TRIGGER z_min_update
29107 BEFORE UPDATE ON tablename
29108 FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger();
29109 </programlisting>
29110 In most cases, you need to fire this trigger last for each row, so that
29111 it does not override other triggers that might wish to alter the row.
29112 Bearing in mind that triggers fire in name order, you would therefore
29113 choose a trigger name that comes after the name of any other trigger
29114 you might have on the table. (Hence the <quote>z</quote> prefix in the
29115 example.)
29116 </para>
29117 </sect1>
29119 <sect1 id="functions-event-triggers">
29120 <title>Event Trigger Functions</title>
29122 <para>
29123 <productname>PostgreSQL</productname> provides these helper functions
29124 to retrieve information from event triggers.
29125 </para>
29127 <para>
29128 For more information about event triggers,
29129 see <xref linkend="event-triggers"/>.
29130 </para>
29132 <sect2 id="pg-event-trigger-ddl-command-end-functions">
29133 <title>Capturing Changes at Command End</title>
29135 <indexterm>
29136 <primary>pg_event_trigger_ddl_commands</primary>
29137 </indexterm>
29139 <synopsis>
29140 <function>pg_event_trigger_ddl_commands</function> () <returnvalue>setof record</returnvalue>
29141 </synopsis>
29143 <para>
29144 <function>pg_event_trigger_ddl_commands</function> returns a list of
29145 <acronym>DDL</acronym> commands executed by each user action,
29146 when invoked in a function attached to a
29147 <literal>ddl_command_end</literal> event trigger. If called in any other
29148 context, an error is raised.
29149 <function>pg_event_trigger_ddl_commands</function> returns one row for each
29150 base command executed; some commands that are a single SQL sentence
29151 may return more than one row. This function returns the following
29152 columns:
29154 <informaltable>
29155 <tgroup cols="3">
29156 <thead>
29157 <row>
29158 <entry>Name</entry>
29159 <entry>Type</entry>
29160 <entry>Description</entry>
29161 </row>
29162 </thead>
29164 <tbody>
29165 <row>
29166 <entry><literal>classid</literal></entry>
29167 <entry><type>oid</type></entry>
29168 <entry>OID of catalog the object belongs in</entry>
29169 </row>
29170 <row>
29171 <entry><literal>objid</literal></entry>
29172 <entry><type>oid</type></entry>
29173 <entry>OID of the object itself</entry>
29174 </row>
29175 <row>
29176 <entry><literal>objsubid</literal></entry>
29177 <entry><type>integer</type></entry>
29178 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
29179 </row>
29180 <row>
29181 <entry><literal>command_tag</literal></entry>
29182 <entry><type>text</type></entry>
29183 <entry>Command tag</entry>
29184 </row>
29185 <row>
29186 <entry><literal>object_type</literal></entry>
29187 <entry><type>text</type></entry>
29188 <entry>Type of the object</entry>
29189 </row>
29190 <row>
29191 <entry><literal>schema_name</literal></entry>
29192 <entry><type>text</type></entry>
29193 <entry>
29194 Name of the schema the object belongs in, if any; otherwise <literal>NULL</literal>.
29195 No quoting is applied.
29196 </entry>
29197 </row>
29198 <row>
29199 <entry><literal>object_identity</literal></entry>
29200 <entry><type>text</type></entry>
29201 <entry>
29202 Text rendering of the object identity, schema-qualified. Each
29203 identifier included in the identity is quoted if necessary.
29204 </entry>
29205 </row>
29206 <row>
29207 <entry><literal>in_extension</literal></entry>
29208 <entry><type>boolean</type></entry>
29209 <entry>True if the command is part of an extension script</entry>
29210 </row>
29211 <row>
29212 <entry><literal>command</literal></entry>
29213 <entry><type>pg_ddl_command</type></entry>
29214 <entry>
29215 A complete representation of the command, in internal format.
29216 This cannot be output directly, but it can be passed to other
29217 functions to obtain different pieces of information about the
29218 command.
29219 </entry>
29220 </row>
29221 </tbody>
29222 </tgroup>
29223 </informaltable>
29224 </para>
29225 </sect2>
29227 <sect2 id="pg-event-trigger-sql-drop-functions">
29228 <title>Processing Objects Dropped by a DDL Command</title>
29230 <indexterm>
29231 <primary>pg_event_trigger_dropped_objects</primary>
29232 </indexterm>
29234 <synopsis>
29235 <function>pg_event_trigger_dropped_objects</function> () <returnvalue>setof record</returnvalue>
29236 </synopsis>
29238 <para>
29239 <function>pg_event_trigger_dropped_objects</function> returns a list of all objects
29240 dropped by the command in whose <literal>sql_drop</literal> event it is called.
29241 If called in any other context, an error is raised.
29242 This function returns the following columns:
29244 <informaltable>
29245 <tgroup cols="3">
29246 <thead>
29247 <row>
29248 <entry>Name</entry>
29249 <entry>Type</entry>
29250 <entry>Description</entry>
29251 </row>
29252 </thead>
29254 <tbody>
29255 <row>
29256 <entry><literal>classid</literal></entry>
29257 <entry><type>oid</type></entry>
29258 <entry>OID of catalog the object belonged in</entry>
29259 </row>
29260 <row>
29261 <entry><literal>objid</literal></entry>
29262 <entry><type>oid</type></entry>
29263 <entry>OID of the object itself</entry>
29264 </row>
29265 <row>
29266 <entry><literal>objsubid</literal></entry>
29267 <entry><type>integer</type></entry>
29268 <entry>Sub-object ID (e.g., attribute number for a column)</entry>
29269 </row>
29270 <row>
29271 <entry><literal>original</literal></entry>
29272 <entry><type>boolean</type></entry>
29273 <entry>True if this was one of the root object(s) of the deletion</entry>
29274 </row>
29275 <row>
29276 <entry><literal>normal</literal></entry>
29277 <entry><type>boolean</type></entry>
29278 <entry>
29279 True if there was a normal dependency relationship
29280 in the dependency graph leading to this object
29281 </entry>
29282 </row>
29283 <row>
29284 <entry><literal>is_temporary</literal></entry>
29285 <entry><type>boolean</type></entry>
29286 <entry>
29287 True if this was a temporary object
29288 </entry>
29289 </row>
29290 <row>
29291 <entry><literal>object_type</literal></entry>
29292 <entry><type>text</type></entry>
29293 <entry>Type of the object</entry>
29294 </row>
29295 <row>
29296 <entry><literal>schema_name</literal></entry>
29297 <entry><type>text</type></entry>
29298 <entry>
29299 Name of the schema the object belonged in, if any; otherwise <literal>NULL</literal>.
29300 No quoting is applied.
29301 </entry>
29302 </row>
29303 <row>
29304 <entry><literal>object_name</literal></entry>
29305 <entry><type>text</type></entry>
29306 <entry>
29307 Name of the object, if the combination of schema and name can be
29308 used as a unique identifier for the object; otherwise <literal>NULL</literal>.
29309 No quoting is applied, and name is never schema-qualified.
29310 </entry>
29311 </row>
29312 <row>
29313 <entry><literal>object_identity</literal></entry>
29314 <entry><type>text</type></entry>
29315 <entry>
29316 Text rendering of the object identity, schema-qualified. Each
29317 identifier included in the identity is quoted if necessary.
29318 </entry>
29319 </row>
29320 <row>
29321 <entry><literal>address_names</literal></entry>
29322 <entry><type>text[]</type></entry>
29323 <entry>
29324 An array that, together with <literal>object_type</literal> and
29325 <literal>address_args</literal>, can be used by
29326 the <function>pg_get_object_address</function> function to
29327 recreate the object address in a remote server containing an
29328 identically named object of the same kind.
29329 </entry>
29330 </row>
29331 <row>
29332 <entry><literal>address_args</literal></entry>
29333 <entry><type>text[]</type></entry>
29334 <entry>
29335 Complement for <literal>address_names</literal>
29336 </entry>
29337 </row>
29338 </tbody>
29339 </tgroup>
29340 </informaltable>
29341 </para>
29343 <para>
29344 The <function>pg_event_trigger_dropped_objects</function> function can be used
29345 in an event trigger like this:
29346 <programlisting>
29347 CREATE FUNCTION test_event_trigger_for_drops()
29348 RETURNS event_trigger LANGUAGE plpgsql AS $$
29349 DECLARE
29350 obj record;
29351 BEGIN
29352 FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
29353 LOOP
29354 RAISE NOTICE '% dropped object: % %.% %',
29355 tg_tag,
29356 obj.object_type,
29357 obj.schema_name,
29358 obj.object_name,
29359 obj.object_identity;
29360 END LOOP;
29361 END;
29363 CREATE EVENT TRIGGER test_event_trigger_for_drops
29364 ON sql_drop
29365 EXECUTE FUNCTION test_event_trigger_for_drops();
29366 </programlisting>
29367 </para>
29368 </sect2>
29370 <sect2 id="pg-event-trigger-table-rewrite-functions">
29371 <title>Handling a Table Rewrite Event</title>
29373 <para>
29374 The functions shown in
29375 <xref linkend="functions-event-trigger-table-rewrite"/>
29376 provide information about a table for which a
29377 <literal>table_rewrite</literal> event has just been called.
29378 If called in any other context, an error is raised.
29379 </para>
29381 <table id="functions-event-trigger-table-rewrite">
29382 <title>Table Rewrite Information Functions</title>
29383 <tgroup cols="1">
29384 <thead>
29385 <row>
29386 <entry role="func_table_entry"><para role="func_signature">
29387 Function
29388 </para>
29389 <para>
29390 Description
29391 </para></entry>
29392 </row>
29393 </thead>
29395 <tbody>
29396 <row>
29397 <entry role="func_table_entry"><para role="func_signature">
29398 <indexterm>
29399 <primary>pg_event_trigger_table_rewrite_oid</primary>
29400 </indexterm>
29401 <function>pg_event_trigger_table_rewrite_oid</function> ()
29402 <returnvalue>oid</returnvalue>
29403 </para>
29404 <para>
29405 Returns the OID of the table about to be rewritten.
29406 </para></entry>
29407 </row>
29409 <row>
29410 <entry role="func_table_entry"><para role="func_signature">
29411 <indexterm>
29412 <primary>pg_event_trigger_table_rewrite_reason</primary>
29413 </indexterm>
29414 <function>pg_event_trigger_table_rewrite_reason</function> ()
29415 <returnvalue>integer</returnvalue>
29416 </para>
29417 <para>
29418 Returns a code explaining the reason(s) for rewriting. The exact
29419 meaning of the codes is release dependent.
29420 </para></entry>
29421 </row>
29422 </tbody>
29423 </tgroup>
29424 </table>
29426 <para>
29427 These functions can be used in an event trigger like this:
29428 <programlisting>
29429 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
29430 RETURNS event_trigger
29431 LANGUAGE plpgsql AS
29433 BEGIN
29434 RAISE NOTICE 'rewriting table % for reason %',
29435 pg_event_trigger_table_rewrite_oid()::regclass,
29436 pg_event_trigger_table_rewrite_reason();
29437 END;
29440 CREATE EVENT TRIGGER test_table_rewrite_oid
29441 ON table_rewrite
29442 EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
29443 </programlisting>
29444 </para>
29445 </sect2>
29446 </sect1>
29448 <sect1 id="functions-statistics">
29449 <title>Statistics Information Functions</title>
29451 <indexterm zone="functions-statistics">
29452 <primary>function</primary>
29453 <secondary>statistics</secondary>
29454 </indexterm>
29456 <para>
29457 <productname>PostgreSQL</productname> provides a function to inspect complex
29458 statistics defined using the <command>CREATE STATISTICS</command> command.
29459 </para>
29461 <sect2 id="functions-statistics-mcv">
29462 <title>Inspecting MCV Lists</title>
29464 <indexterm>
29465 <primary>pg_mcv_list_items</primary>
29466 </indexterm>
29468 <synopsis>
29469 <function>pg_mcv_list_items</function> ( <type>pg_mcv_list</type> ) <returnvalue>setof record</returnvalue>
29470 </synopsis>
29472 <para>
29473 <function>pg_mcv_list_items</function> returns a set of records describing
29474 all items stored in a multi-column <acronym>MCV</acronym> list. It
29475 returns the following columns:
29477 <informaltable>
29478 <tgroup cols="3">
29479 <thead>
29480 <row>
29481 <entry>Name</entry>
29482 <entry>Type</entry>
29483 <entry>Description</entry>
29484 </row>
29485 </thead>
29487 <tbody>
29488 <row>
29489 <entry><literal>index</literal></entry>
29490 <entry><type>integer</type></entry>
29491 <entry>index of the item in the <acronym>MCV</acronym> list</entry>
29492 </row>
29493 <row>
29494 <entry><literal>values</literal></entry>
29495 <entry><type>text[]</type></entry>
29496 <entry>values stored in the MCV item</entry>
29497 </row>
29498 <row>
29499 <entry><literal>nulls</literal></entry>
29500 <entry><type>boolean[]</type></entry>
29501 <entry>flags identifying <literal>NULL</literal> values</entry>
29502 </row>
29503 <row>
29504 <entry><literal>frequency</literal></entry>
29505 <entry><type>double precision</type></entry>
29506 <entry>frequency of this <acronym>MCV</acronym> item</entry>
29507 </row>
29508 <row>
29509 <entry><literal>base_frequency</literal></entry>
29510 <entry><type>double precision</type></entry>
29511 <entry>base frequency of this <acronym>MCV</acronym> item</entry>
29512 </row>
29513 </tbody>
29514 </tgroup>
29515 </informaltable>
29516 </para>
29518 <para>
29519 The <function>pg_mcv_list_items</function> function can be used like this:
29521 <programlisting>
29522 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
29523 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
29524 </programlisting>
29526 Values of the <type>pg_mcv_list</type> type can be obtained only from the
29527 <structname>pg_statistic_ext_data</structname>.<structfield>stxdmcv</structfield>
29528 column.
29529 </para>
29530 </sect2>
29532 </sect1>
29534 </chapter>