1 <!-- doc/src/sgml/func.sgml -->
3 <chapter id=
"functions">
4 <title>Functions and Operators
</title>
6 <indexterm zone=
"functions">
7 <primary>function
</primary>
10 <indexterm zone=
"functions">
11 <primary>operator
</primary>
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.
27 The notation used throughout this chapter to describe the argument and
28 result data types of a function or operator is like this:
30 <function>repeat
</function> (
<type>text
</type>,
<type>integer
</type> )
<returnvalue>text
</returnvalue>
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:
36 repeat('Pg',
4)
<returnvalue>PgPgPgPg
</returnvalue>
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.
52 <sect1 id=
"functions-logical">
53 <title>Logical Operators
</title>
55 <indexterm zone=
"functions-logical">
56 <primary>operator
</primary>
57 <secondary>logical
</secondary>
61 <primary>Boolean
</primary>
62 <secondary>operators
</secondary>
63 <see>operators, logical
</see>
67 The usual logical operators are available:
70 <primary>AND (operator)
</primary>
74 <primary>OR (operator)
</primary>
78 <primary>NOT (operator)
</primary>
82 <primary>conjunction
</primary>
86 <primary>disjunction
</primary>
90 <primary>negation
</primary>
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>
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:
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>
164 <entry><replaceable>a
</replaceable></entry>
165 <entry>NOT
<replaceable>a
</replaceable></entry>
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.)
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>
208 The usual comparison operators are available, as shown in
<xref
209 linkend=
"functions-comparison-op-table"/>.
212 <table id=
"functions-comparison-op-table">
213 <title>Comparison Operators
</title>
217 <entry>Operator
</entry>
218 <entry>Description
</entry>
225 <replaceable>datatype
</replaceable> <literal><</literal> <replaceable>datatype
</replaceable>
226 <returnvalue>boolean
</returnvalue>
228 <entry>Less than
</entry>
233 <replaceable>datatype
</replaceable> <literal>></literal> <replaceable>datatype
</replaceable>
234 <returnvalue>boolean
</returnvalue>
236 <entry>Greater than
</entry>
241 <replaceable>datatype
</replaceable> <literal><=
</literal> <replaceable>datatype
</replaceable>
242 <returnvalue>boolean
</returnvalue>
244 <entry>Less than or equal to
</entry>
249 <replaceable>datatype
</replaceable> <literal>>=
</literal> <replaceable>datatype
</replaceable>
250 <returnvalue>boolean
</returnvalue>
252 <entry>Greater than or equal to
</entry>
257 <replaceable>datatype
</replaceable> <literal>=
</literal> <replaceable>datatype
</replaceable>
258 <returnvalue>boolean
</returnvalue>
265 <replaceable>datatype
</replaceable> <literal><></literal> <replaceable>datatype
</replaceable>
266 <returnvalue>boolean
</returnvalue>
268 <entry>Not equal
</entry>
273 <replaceable>datatype
</replaceable> <literal>!=
</literal> <replaceable>datatype
</replaceable>
274 <returnvalue>boolean
</returnvalue>
276 <entry>Not equal
</entry>
284 <literal><></literal> is the standard SQL notation for
<quote>not
285 equal
</quote>.
<literal>!=
</literal> is an alias, which is converted
286 to
<literal><></literal> at a very early stage of parsing.
287 Hence, it is not possible to implement
<literal>!=
</literal>
288 and
<literal><></literal> operators that do different things.
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.
300 It is usually possible to compare values of related data
301 types as well; for example
<type>integer
</type> <literal>></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.
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 < 2 < 3</literal> are not valid (because there is
312 no
<literal><</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.
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.
323 <table id=
"functions-comparison-pred-table">
324 <title>Comparison Predicates
</title>
328 <entry role=
"func_table_entry"><para role=
"func_signature">
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>
347 Between (inclusive of the range endpoints).
350 <literal>2 BETWEEN
1 AND
3</literal>
351 <returnvalue>t
</returnvalue>
354 <literal>2 BETWEEN
3 AND
1</literal>
355 <returnvalue>f
</returnvalue>
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>
365 Not between (the negation of
<literal>BETWEEN
</literal>).
368 <literal>2 NOT BETWEEN
1 AND
3</literal>
369 <returnvalue>f
</returnvalue>
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>
379 Between, after sorting the two endpoint values.
382 <literal>2 BETWEEN SYMMETRIC
3 AND
1</literal>
383 <returnvalue>t
</returnvalue>
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>
393 Not between, after sorting the two endpoint values.
396 <literal>2 NOT BETWEEN SYMMETRIC
3 AND
1</literal>
397 <returnvalue>f
</returnvalue>
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>
407 Not equal, treating null as a comparable value.
410 <literal>1 IS DISTINCT FROM NULL
</literal>
411 <returnvalue>t
</returnvalue> (rather than
<literal>NULL
</literal>)
414 <literal>NULL IS DISTINCT FROM NULL
</literal>
415 <returnvalue>f
</returnvalue> (rather than
<literal>NULL
</literal>)
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>
425 Equal, treating null as a comparable value.
428 <literal>1 IS NOT DISTINCT FROM NULL
</literal>
429 <returnvalue>f
</returnvalue> (rather than
<literal>NULL
</literal>)
432 <literal>NULL IS NOT DISTINCT FROM NULL
</literal>
433 <returnvalue>t
</returnvalue> (rather than
<literal>NULL
</literal>)
438 <entry role=
"func_table_entry"><para role=
"func_signature">
439 <replaceable>datatype
</replaceable> <literal>IS NULL
</literal>
440 <returnvalue>boolean
</returnvalue>
443 Test whether value is null.
446 <literal>1.5 IS NULL
</literal>
447 <returnvalue>f
</returnvalue>
452 <entry role=
"func_table_entry"><para role=
"func_signature">
453 <replaceable>datatype
</replaceable> <literal>IS NOT NULL
</literal>
454 <returnvalue>boolean
</returnvalue>
457 Test whether value is not null.
460 <literal>'null' IS NOT NULL
</literal>
461 <returnvalue>t
</returnvalue>
466 <entry role=
"func_table_entry"><para role=
"func_signature">
467 <replaceable>datatype
</replaceable> <literal>ISNULL
</literal>
468 <returnvalue>boolean
</returnvalue>
471 Test whether value is null (nonstandard syntax).
476 <entry role=
"func_table_entry"><para role=
"func_signature">
477 <replaceable>datatype
</replaceable> <literal>NOTNULL
</literal>
478 <returnvalue>boolean
</returnvalue>
481 Test whether value is not null (nonstandard syntax).
486 <entry role=
"func_table_entry"><para role=
"func_signature">
487 <type>boolean
</type> <literal>IS TRUE
</literal>
488 <returnvalue>boolean
</returnvalue>
491 Test whether boolean expression yields true.
494 <literal>true IS TRUE
</literal>
495 <returnvalue>t
</returnvalue>
498 <literal>NULL::boolean IS TRUE
</literal>
499 <returnvalue>f
</returnvalue> (rather than
<literal>NULL
</literal>)
504 <entry role=
"func_table_entry"><para role=
"func_signature">
505 <type>boolean
</type> <literal>IS NOT TRUE
</literal>
506 <returnvalue>boolean
</returnvalue>
509 Test whether boolean expression yields false or unknown.
512 <literal>true IS NOT TRUE
</literal>
513 <returnvalue>f
</returnvalue>
516 <literal>NULL::boolean IS NOT TRUE
</literal>
517 <returnvalue>t
</returnvalue> (rather than
<literal>NULL
</literal>)
522 <entry role=
"func_table_entry"><para role=
"func_signature">
523 <type>boolean
</type> <literal>IS FALSE
</literal>
524 <returnvalue>boolean
</returnvalue>
527 Test whether boolean expression yields false.
530 <literal>true IS FALSE
</literal>
531 <returnvalue>f
</returnvalue>
534 <literal>NULL::boolean IS FALSE
</literal>
535 <returnvalue>f
</returnvalue> (rather than
<literal>NULL
</literal>)
540 <entry role=
"func_table_entry"><para role=
"func_signature">
541 <type>boolean
</type> <literal>IS NOT FALSE
</literal>
542 <returnvalue>boolean
</returnvalue>
545 Test whether boolean expression yields true or unknown.
548 <literal>true IS NOT FALSE
</literal>
549 <returnvalue>t
</returnvalue>
552 <literal>NULL::boolean IS NOT FALSE
</literal>
553 <returnvalue>t
</returnvalue> (rather than
<literal>NULL
</literal>)
558 <entry role=
"func_table_entry"><para role=
"func_signature">
559 <type>boolean
</type> <literal>IS UNKNOWN
</literal>
560 <returnvalue>boolean
</returnvalue>
563 Test whether boolean expression yields unknown.
566 <literal>true IS UNKNOWN
</literal>
567 <returnvalue>f
</returnvalue>
570 <literal>NULL::boolean IS UNKNOWN
</literal>
571 <returnvalue>t
</returnvalue> (rather than
<literal>NULL
</literal>)
576 <entry role=
"func_table_entry"><para role=
"func_signature">
577 <type>boolean
</type> <literal>IS NOT UNKNOWN
</literal>
578 <returnvalue>boolean
</returnvalue>
581 Test whether boolean expression yields true or false.
584 <literal>true IS NOT UNKNOWN
</literal>
585 <returnvalue>t
</returnvalue>
588 <literal>NULL::boolean IS NOT UNKNOWN
</literal>
589 <returnvalue>f
</returnvalue> (rather than
<literal>NULL
</literal>)
598 <primary>BETWEEN
</primary>
601 <primary>BETWEEN SYMMETRIC
</primary>
603 The
<token>BETWEEN
</token> predicate simplifies range tests:
605 <replaceable>a
</replaceable> BETWEEN
<replaceable>x
</replaceable> AND
<replaceable>y
</replaceable>
609 <replaceable>a
</replaceable> >=
<replaceable>x
</replaceable> AND
<replaceable>a
</replaceable> <=
<replaceable>y
</replaceable>
611 Notice that
<token>BETWEEN
</token> treats the endpoint values as included
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.
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.
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
640 <primary>IS DISTINCT FROM
</primary>
643 <primary>IS NOT DISTINCT FROM
</primary>
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 <> NULL
</literal>. When
648 this behavior is not suitable, use the
649 <literal>IS
<optional> NOT
</optional> DISTINCT FROM
</literal> predicates:
651 <replaceable>a
</replaceable> IS DISTINCT FROM
<replaceable>b
</replaceable>
652 <replaceable>a
</replaceable> IS NOT DISTINCT FROM
<replaceable>b
</replaceable>
654 For non-null inputs,
<literal>IS DISTINCT FROM
</literal> is
655 the same as the
<literal><></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>.
666 <primary>IS NULL
</primary>
669 <primary>IS NOT NULL
</primary>
672 <primary>ISNULL
</primary>
675 <primary>NOTNULL
</primary>
677 To check whether a value is or is not null, use the predicates:
679 <replaceable>expression
</replaceable> IS NULL
680 <replaceable>expression
</replaceable> IS NOT NULL
682 or the equivalent, but nonstandard, predicates:
684 <replaceable>expression
</replaceable> ISNULL
685 <replaceable>expression
</replaceable> NOTNULL
687 <indexterm><primary>null value
</primary><secondary>comparing
</secondary></indexterm>
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.)
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>.
713 If the
<replaceable>expression
</replaceable> is row-valued, then
714 <literal>IS NULL
</literal> is true when the row expression itself is null
715 or when all the row's fields are null, while
716 <literal>IS NOT NULL
</literal> is true when the row expression itself is non-null
717 and all the row's fields are non-null. Because of this behavior,
718 <literal>IS NULL
</literal> and
<literal>IS NOT NULL
</literal> do not always return
719 inverse results for row-valued expressions; in particular, a row-valued
720 expression that contains both null and non-null fields will return false
721 for both tests. For example:
724 SELECT ROW(
1,
2.5,'this is a test') = ROW(
1,
3, 'not the same');
726 SELECT ROW(table.*) IS NULL FROM table; -- detect all-null rows
728 SELECT ROW(table.*) IS NOT NULL FROM table; -- detect all-non-null rows
730 SELECT NOT(ROW(table.*) IS NOT NULL) FROM TABLE; -- detect at least one null in rows
733 In some cases, it may be preferable to
734 write
<replaceable>row
</replaceable> <literal>IS DISTINCT FROM NULL
</literal>
735 or
<replaceable>row
</replaceable> <literal>IS NOT DISTINCT FROM NULL
</literal>,
736 which will simply check whether the overall row value is null without any
737 additional tests on the row fields.
742 <primary>IS TRUE
</primary>
745 <primary>IS NOT TRUE
</primary>
748 <primary>IS FALSE
</primary>
751 <primary>IS NOT FALSE
</primary>
754 <primary>IS UNKNOWN
</primary>
757 <primary>IS NOT UNKNOWN
</primary>
759 Boolean values can also be tested using the predicates
761 <replaceable>boolean_expression
</replaceable> IS TRUE
762 <replaceable>boolean_expression
</replaceable> IS NOT TRUE
763 <replaceable>boolean_expression
</replaceable> IS FALSE
764 <replaceable>boolean_expression
</replaceable> IS NOT FALSE
765 <replaceable>boolean_expression
</replaceable> IS UNKNOWN
766 <replaceable>boolean_expression
</replaceable> IS NOT UNKNOWN
768 These will always return true or false, never a null value, even when the
770 A null input is treated as the logical value
<quote>unknown
</quote>.
771 Notice that
<literal>IS UNKNOWN
</literal> and
<literal>IS NOT UNKNOWN
</literal> are
772 effectively the same as
<literal>IS NULL
</literal> and
773 <literal>IS NOT NULL
</literal>, respectively, except that the input
774 expression must be of Boolean type.
778 Some comparison-related functions are also available, as shown in
<xref
779 linkend=
"functions-comparison-func-table"/>.
782 <table id=
"functions-comparison-func-table">
783 <title>Comparison Functions
</title>
787 <entry role=
"func_table_entry"><para role=
"func_signature">
801 <entry role=
"func_table_entry"><para role=
"func_signature">
803 <primary>num_nonnulls
</primary>
805 <function>num_nonnulls
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
806 <returnvalue>integer
</returnvalue>
809 Returns the number of non-null arguments.
812 <literal>num_nonnulls(
1, NULL,
2)
</literal>
813 <returnvalue>2</returnvalue>
817 <entry role=
"func_table_entry"><para role=
"func_signature">
819 <primary>num_nulls
</primary>
821 <function>num_nulls
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
822 <returnvalue>integer
</returnvalue>
825 Returns the number of null arguments.
828 <literal>num_nulls(
1, NULL,
2)
</literal>
829 <returnvalue>1</returnvalue>
838 <sect1 id=
"functions-math">
839 <title>Mathematical Functions and Operators
</title>
842 Mathematical operators are provided for many
843 <productname>PostgreSQL
</productname> types. For types without
844 standard mathematical conventions
845 (e.g., date/time types) we
846 describe the actual behavior in subsequent sections.
850 <xref linkend=
"functions-math-op-table"/> shows the mathematical
851 operators that are available for the standard numeric types.
852 Unless otherwise noted, operators shown as
853 accepting
<replaceable>numeric_type
</replaceable> are available for all
854 the types
<type>smallint
</type>,
<type>integer
</type>,
855 <type>bigint
</type>,
<type>numeric
</type>,
<type>real
</type>,
856 and
<type>double precision
</type>.
857 Operators shown as accepting
<replaceable>integral_type
</replaceable>
858 are available for the types
<type>smallint
</type>,
<type>integer
</type>,
859 and
<type>bigint
</type>.
860 Except where noted, each form of an operator returns the same data type
861 as its argument(s). Calls involving multiple argument data types, such
862 as
<type>integer
</type> <literal>+
</literal> <type>numeric
</type>,
863 are resolved by using the type appearing later in these lists.
866 <table id=
"functions-math-op-table">
867 <title>Mathematical Operators
</title>
872 <entry role=
"func_table_entry"><para role=
"func_signature">
886 <entry role=
"func_table_entry"><para role=
"func_signature">
887 <replaceable>numeric_type
</replaceable> <literal>+
</literal> <replaceable>numeric_type
</replaceable>
888 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
894 <literal>2 +
3</literal>
895 <returnvalue>5</returnvalue>
900 <entry role=
"func_table_entry"><para role=
"func_signature">
901 <literal>+
</literal> <replaceable>numeric_type
</replaceable>
902 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
905 Unary plus (no operation)
908 <literal>+
3.5</literal>
909 <returnvalue>3.5</returnvalue>
914 <entry role=
"func_table_entry"><para role=
"func_signature">
915 <replaceable>numeric_type
</replaceable> <literal>-
</literal> <replaceable>numeric_type
</replaceable>
916 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
922 <literal>2 -
3</literal>
923 <returnvalue>-
1</returnvalue>
928 <entry role=
"func_table_entry"><para role=
"func_signature">
929 <literal>-
</literal> <replaceable>numeric_type
</replaceable>
930 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
936 <literal>- (-
4)
</literal>
937 <returnvalue>4</returnvalue>
942 <entry role=
"func_table_entry"><para role=
"func_signature">
943 <replaceable>numeric_type
</replaceable> <literal>*
</literal> <replaceable>numeric_type
</replaceable>
944 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
950 <literal>2 *
3</literal>
951 <returnvalue>6</returnvalue>
956 <entry role=
"func_table_entry"><para role=
"func_signature">
957 <replaceable>numeric_type
</replaceable> <literal>/
</literal> <replaceable>numeric_type
</replaceable>
958 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
961 Division (for integral types, division truncates the result towards
965 <literal>5.0 /
2</literal>
966 <returnvalue>2.5000000000000000</returnvalue>
969 <literal>5 /
2</literal>
970 <returnvalue>2</returnvalue>
973 <literal>(-
5) /
2</literal>
974 <returnvalue>-
2</returnvalue>
979 <entry role=
"func_table_entry"><para role=
"func_signature">
980 <replaceable>numeric_type
</replaceable> <literal>%
</literal> <replaceable>numeric_type
</replaceable>
981 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
984 Modulo (remainder); available for
<type>smallint
</type>,
985 <type>integer
</type>,
<type>bigint
</type>, and
<type>numeric
</type>
988 <literal>5 %
4</literal>
989 <returnvalue>1</returnvalue>
994 <entry role=
"func_table_entry"><para role=
"func_signature">
995 <type>numeric
</type> <literal>^
</literal> <type>numeric
</type>
996 <returnvalue>numeric
</returnvalue>
998 <para role=
"func_signature">
999 <type>double precision
</type> <literal>^
</literal> <type>double precision
</type>
1000 <returnvalue>double precision
</returnvalue>
1006 <literal>2 ^
3</literal>
1007 <returnvalue>8</returnvalue>
1010 Unlike typical mathematical practice, multiple uses of
1011 <literal>^
</literal> will associate left to right by default:
1014 <literal>2 ^
3 ^
3</literal>
1015 <returnvalue>512</returnvalue>
1018 <literal>2 ^ (
3 ^
3)
</literal>
1019 <returnvalue>134217728</returnvalue>
1024 <entry role=
"func_table_entry"><para role=
"func_signature">
1025 <literal>|/
</literal> <type>double precision
</type>
1026 <returnvalue>double precision
</returnvalue>
1032 <literal>|/
25.0</literal>
1033 <returnvalue>5</returnvalue>
1038 <entry role=
"func_table_entry"><para role=
"func_signature">
1039 <literal>||/
</literal> <type>double precision
</type>
1040 <returnvalue>double precision
</returnvalue>
1046 <literal>||/
64.0</literal>
1047 <returnvalue>4</returnvalue>
1052 <entry role=
"func_table_entry"><para role=
"func_signature">
1053 <literal>@
</literal> <replaceable>numeric_type
</replaceable>
1054 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1060 <literal>@ -
5.0</literal>
1061 <returnvalue>5.0</returnvalue>
1066 <entry role=
"func_table_entry"><para role=
"func_signature">
1067 <replaceable>integral_type
</replaceable> <literal>&</literal> <replaceable>integral_type
</replaceable>
1068 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1074 <literal>91 & 15</literal>
1075 <returnvalue>11</returnvalue>
1080 <entry role=
"func_table_entry"><para role=
"func_signature">
1081 <replaceable>integral_type
</replaceable> <literal>|
</literal> <replaceable>integral_type
</replaceable>
1082 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1088 <literal>32 |
3</literal>
1089 <returnvalue>35</returnvalue>
1094 <entry role=
"func_table_entry"><para role=
"func_signature">
1095 <replaceable>integral_type
</replaceable> <literal>#
</literal> <replaceable>integral_type
</replaceable>
1096 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1099 Bitwise exclusive OR
1102 <literal>17 #
5</literal>
1103 <returnvalue>20</returnvalue>
1108 <entry role=
"func_table_entry"><para role=
"func_signature">
1109 <literal>~
</literal> <replaceable>integral_type
</replaceable>
1110 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1116 <literal>~
1</literal>
1117 <returnvalue>-
2</returnvalue>
1122 <entry role=
"func_table_entry"><para role=
"func_signature">
1123 <replaceable>integral_type
</replaceable> <literal><<</literal> <type>integer
</type>
1124 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1130 <literal>1 << 4</literal>
1131 <returnvalue>16</returnvalue>
1136 <entry role=
"func_table_entry"><para role=
"func_signature">
1137 <replaceable>integral_type
</replaceable> <literal>>></literal> <type>integer
</type>
1138 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1144 <literal>8 >> 2</literal>
1145 <returnvalue>2</returnvalue>
1154 <xref linkend=
"functions-math-func-table"/> shows the available
1155 mathematical functions.
1156 Many of these functions are provided in multiple forms with different
1158 Except where noted, any given form of a function returns the same
1159 data type as its argument(s); cross-type cases are resolved in the
1160 same way as explained above for operators.
1161 The functions working with
<type>double precision
</type> data are mostly
1162 implemented on top of the host system's C library; accuracy and behavior in
1163 boundary cases can therefore vary depending on the host system.
1166 <table id=
"functions-math-func-table">
1167 <title>Mathematical Functions
</title>
1171 <entry role=
"func_table_entry"><para role=
"func_signature">
1185 <entry role=
"func_table_entry"><para role=
"func_signature">
1187 <primary>abs
</primary>
1189 <function>abs
</function> (
<replaceable>numeric_type
</replaceable> )
1190 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1196 <literal>abs(-
17.4)
</literal>
1197 <returnvalue>17.4</returnvalue>
1202 <entry role=
"func_table_entry"><para role=
"func_signature">
1204 <primary>cbrt
</primary>
1206 <function>cbrt
</function> (
<type>double precision
</type> )
1207 <returnvalue>double precision
</returnvalue>
1213 <literal>cbrt(
64.0)
</literal>
1214 <returnvalue>4</returnvalue>
1219 <entry role=
"func_table_entry"><para role=
"func_signature">
1221 <primary>ceil
</primary>
1223 <function>ceil
</function> (
<type>numeric
</type> )
1224 <returnvalue>numeric
</returnvalue>
1226 <para role=
"func_signature">
1227 <function>ceil
</function> (
<type>double precision
</type> )
1228 <returnvalue>double precision
</returnvalue>
1231 Nearest integer greater than or equal to argument
1234 <literal>ceil(
42.2)
</literal>
1235 <returnvalue>43</returnvalue>
1238 <literal>ceil(-
42.8)
</literal>
1239 <returnvalue>-
42</returnvalue>
1244 <entry role=
"func_table_entry"><para role=
"func_signature">
1246 <primary>ceiling
</primary>
1248 <function>ceiling
</function> (
<type>numeric
</type> )
1249 <returnvalue>numeric
</returnvalue>
1251 <para role=
"func_signature">
1252 <function>ceiling
</function> (
<type>double precision
</type> )
1253 <returnvalue>double precision
</returnvalue>
1256 Nearest integer greater than or equal to argument (same
1257 as
<function>ceil
</function>)
1260 <literal>ceiling(
95.3)
</literal>
1261 <returnvalue>96</returnvalue>
1266 <entry role=
"func_table_entry"><para role=
"func_signature">
1268 <primary>degrees
</primary>
1270 <function>degrees
</function> (
<type>double precision
</type> )
1271 <returnvalue>double precision
</returnvalue>
1274 Converts radians to degrees
1277 <literal>degrees(
0.5)
</literal>
1278 <returnvalue>28.64788975654116</returnvalue>
1283 <entry role=
"func_table_entry"><para role=
"func_signature">
1285 <primary>div
</primary>
1287 <function>div
</function> (
<parameter>y
</parameter> <type>numeric
</type>,
1288 <parameter>x
</parameter> <type>numeric
</type> )
1289 <returnvalue>numeric
</returnvalue>
1292 Integer quotient of
<parameter>y
</parameter>/
<parameter>x
</parameter>
1293 (truncates towards zero)
1296 <literal>div(
9,
4)
</literal>
1297 <returnvalue>2</returnvalue>
1302 <entry role=
"func_table_entry"><para role=
"func_signature">
1304 <primary>erf
</primary>
1306 <function>erf
</function> (
<type>double precision
</type> )
1307 <returnvalue>double precision
</returnvalue>
1313 <literal>erf(
1.0)
</literal>
1314 <returnvalue>0.8427007929497149</returnvalue>
1319 <entry role=
"func_table_entry"><para role=
"func_signature">
1321 <primary>erfc
</primary>
1323 <function>erfc
</function> (
<type>double precision
</type> )
1324 <returnvalue>double precision
</returnvalue>
1327 Complementary error function (
<literal>1 - erf(x)
</literal>, without
1328 loss of precision for large inputs)
1331 <literal>erfc(
1.0)
</literal>
1332 <returnvalue>0.15729920705028513</returnvalue>
1337 <entry role=
"func_table_entry"><para role=
"func_signature">
1339 <primary>exp
</primary>
1341 <function>exp
</function> (
<type>numeric
</type> )
1342 <returnvalue>numeric
</returnvalue>
1344 <para role=
"func_signature">
1345 <function>exp
</function> (
<type>double precision
</type> )
1346 <returnvalue>double precision
</returnvalue>
1349 Exponential (
<literal>e
</literal> raised to the given power)
1352 <literal>exp(
1.0)
</literal>
1353 <returnvalue>2.7182818284590452</returnvalue>
1358 <entry role=
"func_table_entry"><para role=
"func_signature">
1359 <indexterm id=
"function-factorial">
1360 <primary>factorial
</primary>
1362 <function>factorial
</function> (
<type>bigint
</type> )
1363 <returnvalue>numeric
</returnvalue>
1369 <literal>factorial(
5)
</literal>
1370 <returnvalue>120</returnvalue>
1375 <entry role=
"func_table_entry"><para role=
"func_signature">
1377 <primary>floor
</primary>
1379 <function>floor
</function> (
<type>numeric
</type> )
1380 <returnvalue>numeric
</returnvalue>
1382 <para role=
"func_signature">
1383 <function>floor
</function> (
<type>double precision
</type> )
1384 <returnvalue>double precision
</returnvalue>
1387 Nearest integer less than or equal to argument
1390 <literal>floor(
42.8)
</literal>
1391 <returnvalue>42</returnvalue>
1394 <literal>floor(-
42.8)
</literal>
1395 <returnvalue>-
43</returnvalue>
1400 <entry role=
"func_table_entry"><para role=
"func_signature">
1402 <primary>gcd
</primary>
1404 <function>gcd
</function> (
<replaceable>numeric_type
</replaceable>,
<replaceable>numeric_type
</replaceable> )
1405 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1408 Greatest common divisor (the largest positive number that divides both
1409 inputs with no remainder); returns
<literal>0</literal> if both inputs
1410 are zero; available for
<type>integer
</type>,
<type>bigint
</type>,
1411 and
<type>numeric
</type>
1414 <literal>gcd(
1071,
462)
</literal>
1415 <returnvalue>21</returnvalue>
1420 <entry role=
"func_table_entry"><para role=
"func_signature">
1422 <primary>lcm
</primary>
1424 <function>lcm
</function> (
<replaceable>numeric_type
</replaceable>,
<replaceable>numeric_type
</replaceable> )
1425 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1428 Least common multiple (the smallest strictly positive number that is
1429 an integral multiple of both inputs); returns
<literal>0</literal> if
1430 either input is zero; available for
<type>integer
</type>,
1431 <type>bigint
</type>, and
<type>numeric
</type>
1434 <literal>lcm(
1071,
462)
</literal>
1435 <returnvalue>23562</returnvalue>
1440 <entry role=
"func_table_entry"><para role=
"func_signature">
1442 <primary>ln
</primary>
1444 <function>ln
</function> (
<type>numeric
</type> )
1445 <returnvalue>numeric
</returnvalue>
1447 <para role=
"func_signature">
1448 <function>ln
</function> (
<type>double precision
</type> )
1449 <returnvalue>double precision
</returnvalue>
1455 <literal>ln(
2.0)
</literal>
1456 <returnvalue>0.6931471805599453</returnvalue>
1461 <entry role=
"func_table_entry"><para role=
"func_signature">
1463 <primary>log
</primary>
1465 <function>log
</function> (
<type>numeric
</type> )
1466 <returnvalue>numeric
</returnvalue>
1468 <para role=
"func_signature">
1469 <function>log
</function> (
<type>double precision
</type> )
1470 <returnvalue>double precision
</returnvalue>
1476 <literal>log(
100)
</literal>
1477 <returnvalue>2</returnvalue>
1482 <entry role=
"func_table_entry"><para role=
"func_signature">
1484 <primary>log10
</primary>
1486 <function>log10
</function> (
<type>numeric
</type> )
1487 <returnvalue>numeric
</returnvalue>
1489 <para role=
"func_signature">
1490 <function>log10
</function> (
<type>double precision
</type> )
1491 <returnvalue>double precision
</returnvalue>
1494 Base
10 logarithm (same as
<function>log
</function>)
1497 <literal>log10(
1000)
</literal>
1498 <returnvalue>3</returnvalue>
1503 <entry role=
"func_table_entry"><para role=
"func_signature">
1504 <function>log
</function> (
<parameter>b
</parameter> <type>numeric
</type>,
1505 <parameter>x
</parameter> <type>numeric
</type> )
1506 <returnvalue>numeric
</returnvalue>
1509 Logarithm of
<parameter>x
</parameter> to base
<parameter>b
</parameter>
1512 <literal>log(
2.0,
64.0)
</literal>
1513 <returnvalue>6.0000000000000000</returnvalue>
1518 <entry role=
"func_table_entry"><para role=
"func_signature">
1520 <primary>min_scale
</primary>
1522 <function>min_scale
</function> (
<type>numeric
</type> )
1523 <returnvalue>integer
</returnvalue>
1526 Minimum scale (number of fractional decimal digits) needed
1527 to represent the supplied value precisely
1530 <literal>min_scale(
8.4100)
</literal>
1531 <returnvalue>2</returnvalue>
1536 <entry role=
"func_table_entry"><para role=
"func_signature">
1538 <primary>mod
</primary>
1540 <function>mod
</function> (
<parameter>y
</parameter> <replaceable>numeric_type
</replaceable>,
1541 <parameter>x
</parameter> <replaceable>numeric_type
</replaceable> )
1542 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1545 Remainder of
<parameter>y
</parameter>/
<parameter>x
</parameter>;
1546 available for
<type>smallint
</type>,
<type>integer
</type>,
1547 <type>bigint
</type>, and
<type>numeric
</type>
1550 <literal>mod(
9,
4)
</literal>
1551 <returnvalue>1</returnvalue>
1556 <entry role=
"func_table_entry"><para role=
"func_signature">
1558 <primary>pi
</primary>
1560 <function>pi
</function> ( )
1561 <returnvalue>double precision
</returnvalue>
1564 Approximate value of
<phrase role=
"symbol_font">π</phrase>
1567 <literal>pi()
</literal>
1568 <returnvalue>3.141592653589793</returnvalue>
1573 <entry role=
"func_table_entry"><para role=
"func_signature">
1575 <primary>power
</primary>
1577 <function>power
</function> (
<parameter>a
</parameter> <type>numeric
</type>,
1578 <parameter>b
</parameter> <type>numeric
</type> )
1579 <returnvalue>numeric
</returnvalue>
1581 <para role=
"func_signature">
1582 <function>power
</function> (
<parameter>a
</parameter> <type>double precision
</type>,
1583 <parameter>b
</parameter> <type>double precision
</type> )
1584 <returnvalue>double precision
</returnvalue>
1587 <parameter>a
</parameter> raised to the power of
<parameter>b
</parameter>
1590 <literal>power(
9,
3)
</literal>
1591 <returnvalue>729</returnvalue>
1596 <entry role=
"func_table_entry"><para role=
"func_signature">
1598 <primary>radians
</primary>
1600 <function>radians
</function> (
<type>double precision
</type> )
1601 <returnvalue>double precision
</returnvalue>
1604 Converts degrees to radians
1607 <literal>radians(
45.0)
</literal>
1608 <returnvalue>0.7853981633974483</returnvalue>
1613 <entry role=
"func_table_entry"><para role=
"func_signature">
1615 <primary>round
</primary>
1617 <function>round
</function> (
<type>numeric
</type> )
1618 <returnvalue>numeric
</returnvalue>
1620 <para role=
"func_signature">
1621 <function>round
</function> (
<type>double precision
</type> )
1622 <returnvalue>double precision
</returnvalue>
1625 Rounds to nearest integer. For
<type>numeric
</type>, ties are
1626 broken by rounding away from zero. For
<type>double precision
</type>,
1627 the tie-breaking behavior is platform dependent, but
1628 <quote>round to nearest even
</quote> is the most common rule.
1631 <literal>round(
42.4)
</literal>
1632 <returnvalue>42</returnvalue>
1637 <entry role=
"func_table_entry"><para role=
"func_signature">
1638 <function>round
</function> (
<parameter>v
</parameter> <type>numeric
</type>,
<parameter>s
</parameter> <type>integer
</type> )
1639 <returnvalue>numeric
</returnvalue>
1642 Rounds
<parameter>v
</parameter> to
<parameter>s
</parameter> decimal
1643 places. Ties are broken by rounding away from zero.
1646 <literal>round(
42.4382,
2)
</literal>
1647 <returnvalue>42.44</returnvalue>
1650 <literal>round(
1234.56, -
1)
</literal>
1651 <returnvalue>1230</returnvalue>
1656 <entry role=
"func_table_entry"><para role=
"func_signature">
1658 <primary>scale
</primary>
1660 <function>scale
</function> (
<type>numeric
</type> )
1661 <returnvalue>integer
</returnvalue>
1664 Scale of the argument (the number of decimal digits in the fractional part)
1667 <literal>scale(
8.4100)
</literal>
1668 <returnvalue>4</returnvalue>
1673 <entry role=
"func_table_entry"><para role=
"func_signature">
1675 <primary>sign
</primary>
1677 <function>sign
</function> (
<type>numeric
</type> )
1678 <returnvalue>numeric
</returnvalue>
1680 <para role=
"func_signature">
1681 <function>sign
</function> (
<type>double precision
</type> )
1682 <returnvalue>double precision
</returnvalue>
1685 Sign of the argument (-
1,
0, or +
1)
1688 <literal>sign(-
8.4)
</literal>
1689 <returnvalue>-
1</returnvalue>
1694 <entry role=
"func_table_entry"><para role=
"func_signature">
1696 <primary>sqrt
</primary>
1698 <function>sqrt
</function> (
<type>numeric
</type> )
1699 <returnvalue>numeric
</returnvalue>
1701 <para role=
"func_signature">
1702 <function>sqrt
</function> (
<type>double precision
</type> )
1703 <returnvalue>double precision
</returnvalue>
1709 <literal>sqrt(
2)
</literal>
1710 <returnvalue>1.4142135623730951</returnvalue>
1715 <entry role=
"func_table_entry"><para role=
"func_signature">
1717 <primary>trim_scale
</primary>
1719 <function>trim_scale
</function> (
<type>numeric
</type> )
1720 <returnvalue>numeric
</returnvalue>
1723 Reduces the value's scale (number of fractional decimal digits) by
1724 removing trailing zeroes
1727 <literal>trim_scale(
8.4100)
</literal>
1728 <returnvalue>8.41</returnvalue>
1733 <entry role=
"func_table_entry"><para role=
"func_signature">
1735 <primary>trunc
</primary>
1737 <function>trunc
</function> (
<type>numeric
</type> )
1738 <returnvalue>numeric
</returnvalue>
1740 <para role=
"func_signature">
1741 <function>trunc
</function> (
<type>double precision
</type> )
1742 <returnvalue>double precision
</returnvalue>
1745 Truncates to integer (towards zero)
1748 <literal>trunc(
42.8)
</literal>
1749 <returnvalue>42</returnvalue>
1752 <literal>trunc(-
42.8)
</literal>
1753 <returnvalue>-
42</returnvalue>
1758 <entry role=
"func_table_entry"><para role=
"func_signature">
1759 <function>trunc
</function> (
<parameter>v
</parameter> <type>numeric
</type>,
<parameter>s
</parameter> <type>integer
</type> )
1760 <returnvalue>numeric
</returnvalue>
1763 Truncates
<parameter>v
</parameter> to
<parameter>s
</parameter>
1767 <literal>trunc(
42.4382,
2)
</literal>
1768 <returnvalue>42.43</returnvalue>
1773 <entry role=
"func_table_entry"><para role=
"func_signature">
1775 <primary>width_bucket
</primary>
1777 <function>width_bucket
</function> (
<parameter>operand
</parameter> <type>numeric
</type>,
<parameter>low
</parameter> <type>numeric
</type>,
<parameter>high
</parameter> <type>numeric
</type>,
<parameter>count
</parameter> <type>integer
</type> )
1778 <returnvalue>integer
</returnvalue>
1780 <para role=
"func_signature">
1781 <function>width_bucket
</function> (
<parameter>operand
</parameter> <type>double precision
</type>,
<parameter>low
</parameter> <type>double precision
</type>,
<parameter>high
</parameter> <type>double precision
</type>,
<parameter>count
</parameter> <type>integer
</type> )
1782 <returnvalue>integer
</returnvalue>
1785 Returns the number of the bucket in
1786 which
<parameter>operand
</parameter> falls in a histogram
1787 having
<parameter>count
</parameter> equal-width buckets spanning the
1788 range
<parameter>low
</parameter> to
<parameter>high
</parameter>.
1789 Returns
<literal>0</literal>
1790 or
<literal><parameter>count
</parameter>+
1</literal> for an input
1794 <literal>width_bucket(
5.35,
0.024,
10.06,
5)
</literal>
1795 <returnvalue>3</returnvalue>
1800 <entry role=
"func_table_entry"><para role=
"func_signature">
1801 <function>width_bucket
</function> (
<parameter>operand
</parameter> <type>anycompatible
</type>,
<parameter>thresholds
</parameter> <type>anycompatiblearray
</type> )
1802 <returnvalue>integer
</returnvalue>
1805 Returns the number of the bucket in
1806 which
<parameter>operand
</parameter> falls given an array listing the
1807 lower bounds of the buckets. Returns
<literal>0</literal> for an
1808 input less than the first lower
1809 bound.
<parameter>operand
</parameter> and the array elements can be
1810 of any type having standard comparison operators.
1811 The
<parameter>thresholds
</parameter> array
<emphasis>must be
1812 sorted
</emphasis>, smallest first, or unexpected results will be
1816 <literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])
</literal>
1817 <returnvalue>2</returnvalue>
1825 <xref linkend=
"functions-math-random-table"/> shows functions for
1826 generating random numbers.
1829 <table id=
"functions-math-random-table">
1830 <title>Random Functions
</title>
1835 <entry role=
"func_table_entry"><para role=
"func_signature">
1849 <entry role=
"func_table_entry"><para role=
"func_signature">
1851 <primary>random
</primary>
1853 <function>random
</function> ( )
1854 <returnvalue>double precision
</returnvalue>
1857 Returns a random value in the range
0.0 <= x
< 1.0
1860 <literal>random()
</literal>
1861 <returnvalue>0.897124072839091</returnvalue>
1866 <entry role=
"func_table_entry"><para role=
"func_signature">
1868 <primary>random
</primary>
1870 <function>random
</function> (
<parameter>min
</parameter> <type>integer
</type>,
<parameter>max
</parameter> <type>integer
</type> )
1871 <returnvalue>integer
</returnvalue>
1873 <para role=
"func_signature">
1874 <function>random
</function> (
<parameter>min
</parameter> <type>bigint
</type>,
<parameter>max
</parameter> <type>bigint
</type> )
1875 <returnvalue>bigint
</returnvalue>
1877 <para role=
"func_signature">
1878 <function>random
</function> (
<parameter>min
</parameter> <type>numeric
</type>,
<parameter>max
</parameter> <type>numeric
</type> )
1879 <returnvalue>numeric
</returnvalue>
1882 Returns a random value in the range
1883 <parameter>min
</parameter> <= x
<=
<parameter>max
</parameter>.
1884 For type
<type>numeric
</type>, the result will have the same number of
1885 fractional decimal digits as
<parameter>min
</parameter> or
1886 <parameter>max
</parameter>, whichever has more.
1889 <literal>random(
1,
10)
</literal>
1890 <returnvalue>7</returnvalue>
1893 <literal>random(-
0.499,
0.499)
</literal>
1894 <returnvalue>0.347</returnvalue>
1899 <entry role=
"func_table_entry"><para role=
"func_signature">
1901 <primary>random_normal
</primary>
1904 <function>random_normal
</function> (
1905 <optional> <parameter>mean
</parameter> <type>double precision
</type>
1906 <optional>,
<parameter>stddev
</parameter> <type>double precision
</type> </optional></optional> )
1907 <returnvalue>double precision
</returnvalue>
1910 Returns a random value from the normal distribution with the given
1911 parameters;
<parameter>mean
</parameter> defaults to
0.0
1912 and
<parameter>stddev
</parameter> defaults to
1.0
1915 <literal>random_normal(
0.0,
1.0)
</literal>
1916 <returnvalue>0.051285419</returnvalue>
1921 <entry role=
"func_table_entry"><para role=
"func_signature">
1923 <primary>setseed
</primary>
1925 <function>setseed
</function> (
<type>double precision
</type> )
1926 <returnvalue>void
</returnvalue>
1929 Sets the seed for subsequent
<literal>random()
</literal> and
1930 <literal>random_normal()
</literal> calls;
1931 argument must be between -
1.0 and
1.0, inclusive
1934 <literal>setseed(
0.12345)
</literal>
1942 The
<function>random()
</function> and
<function>random_normal()
</function>
1943 functions listed in
<xref linkend=
"functions-math-random-table"/> use a
1944 deterministic pseudo-random number generator.
1945 It is fast but not suitable for cryptographic
1946 applications; see the
<xref linkend=
"pgcrypto"/> module for a more
1948 If
<function>setseed()
</function> is called, the series of results of
1949 subsequent calls to these functions in the current session
1950 can be repeated by re-issuing
<function>setseed()
</function> with the same
1952 Without any prior
<function>setseed()
</function> call in the same
1953 session, the first call to any of these functions obtains a seed
1954 from a platform-dependent source of random bits.
1958 <xref linkend=
"functions-math-trig-table"/> shows the
1959 available trigonometric functions. Each of these functions comes in
1960 two variants, one that measures angles in radians and one that
1961 measures angles in degrees.
1964 <table id=
"functions-math-trig-table">
1965 <title>Trigonometric Functions
</title>
1970 <entry role=
"func_table_entry"><para role=
"func_signature">
1984 <entry role=
"func_table_entry"><para role=
"func_signature">
1986 <primary>acos
</primary>
1988 <function>acos
</function> (
<type>double precision
</type> )
1989 <returnvalue>double precision
</returnvalue>
1992 Inverse cosine, result in radians
1995 <literal>acos(
1)
</literal>
1996 <returnvalue>0</returnvalue>
2001 <entry role=
"func_table_entry"><para role=
"func_signature">
2003 <primary>acosd
</primary>
2005 <function>acosd
</function> (
<type>double precision
</type> )
2006 <returnvalue>double precision
</returnvalue>
2009 Inverse cosine, result in degrees
2012 <literal>acosd(
0.5)
</literal>
2013 <returnvalue>60</returnvalue>
2018 <entry role=
"func_table_entry"><para role=
"func_signature">
2020 <primary>asin
</primary>
2022 <function>asin
</function> (
<type>double precision
</type> )
2023 <returnvalue>double precision
</returnvalue>
2026 Inverse sine, result in radians
2029 <literal>asin(
1)
</literal>
2030 <returnvalue>1.5707963267948966</returnvalue>
2035 <entry role=
"func_table_entry"><para role=
"func_signature">
2037 <primary>asind
</primary>
2039 <function>asind
</function> (
<type>double precision
</type> )
2040 <returnvalue>double precision
</returnvalue>
2043 Inverse sine, result in degrees
2046 <literal>asind(
0.5)
</literal>
2047 <returnvalue>30</returnvalue>
2052 <entry role=
"func_table_entry"><para role=
"func_signature">
2054 <primary>atan
</primary>
2056 <function>atan
</function> (
<type>double precision
</type> )
2057 <returnvalue>double precision
</returnvalue>
2060 Inverse tangent, result in radians
2063 <literal>atan(
1)
</literal>
2064 <returnvalue>0.7853981633974483</returnvalue>
2069 <entry role=
"func_table_entry"><para role=
"func_signature">
2071 <primary>atand
</primary>
2073 <function>atand
</function> (
<type>double precision
</type> )
2074 <returnvalue>double precision
</returnvalue>
2077 Inverse tangent, result in degrees
2080 <literal>atand(
1)
</literal>
2081 <returnvalue>45</returnvalue>
2086 <entry role=
"func_table_entry"><para role=
"func_signature">
2088 <primary>atan2
</primary>
2090 <function>atan2
</function> (
<parameter>y
</parameter> <type>double precision
</type>,
2091 <parameter>x
</parameter> <type>double precision
</type> )
2092 <returnvalue>double precision
</returnvalue>
2096 <parameter>y
</parameter>/
<parameter>x
</parameter>,
2100 <literal>atan2(
1,
0)
</literal>
2101 <returnvalue>1.5707963267948966</returnvalue>
2106 <entry role=
"func_table_entry"><para role=
"func_signature">
2108 <primary>atan2d
</primary>
2110 <function>atan2d
</function> (
<parameter>y
</parameter> <type>double precision
</type>,
2111 <parameter>x
</parameter> <type>double precision
</type> )
2112 <returnvalue>double precision
</returnvalue>
2116 <parameter>y
</parameter>/
<parameter>x
</parameter>,
2120 <literal>atan2d(
1,
0)
</literal>
2121 <returnvalue>90</returnvalue>
2126 <entry role=
"func_table_entry"><para role=
"func_signature">
2128 <primary>cos
</primary>
2130 <function>cos
</function> (
<type>double precision
</type> )
2131 <returnvalue>double precision
</returnvalue>
2134 Cosine, argument in radians
2137 <literal>cos(
0)
</literal>
2138 <returnvalue>1</returnvalue>
2143 <entry role=
"func_table_entry"><para role=
"func_signature">
2145 <primary>cosd
</primary>
2147 <function>cosd
</function> (
<type>double precision
</type> )
2148 <returnvalue>double precision
</returnvalue>
2151 Cosine, argument in degrees
2154 <literal>cosd(
60)
</literal>
2155 <returnvalue>0.5</returnvalue>
2160 <entry role=
"func_table_entry"><para role=
"func_signature">
2162 <primary>cot
</primary>
2164 <function>cot
</function> (
<type>double precision
</type> )
2165 <returnvalue>double precision
</returnvalue>
2168 Cotangent, argument in radians
2171 <literal>cot(
0.5)
</literal>
2172 <returnvalue>1.830487721712452</returnvalue>
2177 <entry role=
"func_table_entry"><para role=
"func_signature">
2179 <primary>cotd
</primary>
2181 <function>cotd
</function> (
<type>double precision
</type> )
2182 <returnvalue>double precision
</returnvalue>
2185 Cotangent, argument in degrees
2188 <literal>cotd(
45)
</literal>
2189 <returnvalue>1</returnvalue>
2194 <entry role=
"func_table_entry"><para role=
"func_signature">
2196 <primary>sin
</primary>
2198 <function>sin
</function> (
<type>double precision
</type> )
2199 <returnvalue>double precision
</returnvalue>
2202 Sine, argument in radians
2205 <literal>sin(
1)
</literal>
2206 <returnvalue>0.8414709848078965</returnvalue>
2211 <entry role=
"func_table_entry"><para role=
"func_signature">
2213 <primary>sind
</primary>
2215 <function>sind
</function> (
<type>double precision
</type> )
2216 <returnvalue>double precision
</returnvalue>
2219 Sine, argument in degrees
2222 <literal>sind(
30)
</literal>
2223 <returnvalue>0.5</returnvalue>
2228 <entry role=
"func_table_entry"><para role=
"func_signature">
2230 <primary>tan
</primary>
2232 <function>tan
</function> (
<type>double precision
</type> )
2233 <returnvalue>double precision
</returnvalue>
2236 Tangent, argument in radians
2239 <literal>tan(
1)
</literal>
2240 <returnvalue>1.5574077246549023</returnvalue>
2245 <entry role=
"func_table_entry"><para role=
"func_signature">
2247 <primary>tand
</primary>
2249 <function>tand
</function> (
<type>double precision
</type> )
2250 <returnvalue>double precision
</returnvalue>
2253 Tangent, argument in degrees
2256 <literal>tand(
45)
</literal>
2257 <returnvalue>1</returnvalue>
2266 Another way to work with angles measured in degrees is to use the unit
2267 transformation functions
<literal><function>radians()
</function></literal>
2268 and
<literal><function>degrees()
</function></literal> shown earlier.
2269 However, using the degree-based trigonometric functions is preferred,
2270 as that way avoids round-off error for special cases such
2271 as
<literal>sind(
30)
</literal>.
2276 <xref linkend=
"functions-math-hyp-table"/> shows the
2277 available hyperbolic functions.
2280 <table id=
"functions-math-hyp-table">
2281 <title>Hyperbolic Functions
</title>
2286 <entry role=
"func_table_entry"><para role=
"func_signature">
2300 <entry role=
"func_table_entry"><para role=
"func_signature">
2302 <primary>sinh
</primary>
2304 <function>sinh
</function> (
<type>double precision
</type> )
2305 <returnvalue>double precision
</returnvalue>
2311 <literal>sinh(
1)
</literal>
2312 <returnvalue>1.1752011936438014</returnvalue>
2317 <entry role=
"func_table_entry"><para role=
"func_signature">
2319 <primary>cosh
</primary>
2321 <function>cosh
</function> (
<type>double precision
</type> )
2322 <returnvalue>double precision
</returnvalue>
2328 <literal>cosh(
0)
</literal>
2329 <returnvalue>1</returnvalue>
2334 <entry role=
"func_table_entry"><para role=
"func_signature">
2336 <primary>tanh
</primary>
2338 <function>tanh
</function> (
<type>double precision
</type> )
2339 <returnvalue>double precision
</returnvalue>
2345 <literal>tanh(
1)
</literal>
2346 <returnvalue>0.7615941559557649</returnvalue>
2351 <entry role=
"func_table_entry"><para role=
"func_signature">
2353 <primary>asinh
</primary>
2355 <function>asinh
</function> (
<type>double precision
</type> )
2356 <returnvalue>double precision
</returnvalue>
2359 Inverse hyperbolic sine
2362 <literal>asinh(
1)
</literal>
2363 <returnvalue>0.881373587019543</returnvalue>
2368 <entry role=
"func_table_entry"><para role=
"func_signature">
2370 <primary>acosh
</primary>
2372 <function>acosh
</function> (
<type>double precision
</type> )
2373 <returnvalue>double precision
</returnvalue>
2376 Inverse hyperbolic cosine
2379 <literal>acosh(
1)
</literal>
2380 <returnvalue>0</returnvalue>
2385 <entry role=
"func_table_entry"><para role=
"func_signature">
2387 <primary>atanh
</primary>
2389 <function>atanh
</function> (
<type>double precision
</type> )
2390 <returnvalue>double precision
</returnvalue>
2393 Inverse hyperbolic tangent
2396 <literal>atanh(
0.5)
</literal>
2397 <returnvalue>0.5493061443340548</returnvalue>
2407 <sect1 id=
"functions-string">
2408 <title>String Functions and Operators
</title>
2411 This section describes functions and operators for examining and
2412 manipulating string values. Strings in this context include values
2413 of the types
<type>character
</type>,
<type>character varying
</type>,
2414 and
<type>text
</type>. Except where noted, these functions and operators
2415 are declared to accept and return type
<type>text
</type>. They will
2416 interchangeably accept
<type>character varying
</type> arguments.
2417 Values of type
<type>character
</type> will be converted
2418 to
<type>text
</type> before the function or operator is applied, resulting
2419 in stripping any trailing spaces in the
<type>character
</type> value.
2423 <acronym>SQL
</acronym> defines some string functions that use
2424 key words, rather than commas, to separate
2425 arguments. Details are in
2426 <xref linkend=
"functions-string-sql"/>.
2427 <productname>PostgreSQL
</productname> also provides versions of these functions
2428 that use the regular function invocation syntax
2429 (see
<xref linkend=
"functions-string-other"/>).
2434 The string concatenation operator (
<literal>||
</literal>) will accept
2435 non-string input, so long as at least one input is of string type, as shown
2436 in
<xref linkend=
"functions-string-sql"/>. For other cases, inserting an
2437 explicit coercion to
<type>text
</type> can be used to have non-string input
2442 <table id=
"functions-string-sql">
2443 <title><acronym>SQL
</acronym> String Functions and Operators
</title>
2447 <entry role=
"func_table_entry"><para role=
"func_signature">
2461 <entry role=
"func_table_entry"><para role=
"func_signature">
2463 <primary>character string
</primary>
2464 <secondary>concatenation
</secondary>
2466 <type>text
</type> <literal>||
</literal> <type>text
</type>
2467 <returnvalue>text
</returnvalue>
2470 Concatenates the two strings.
2473 <literal>'Post' || 'greSQL'
</literal>
2474 <returnvalue>PostgreSQL
</returnvalue>
2479 <entry role=
"func_table_entry"><para role=
"func_signature">
2480 <type>text
</type> <literal>||
</literal> <type>anynonarray
</type>
2481 <returnvalue>text
</returnvalue>
2483 <para role=
"func_signature">
2484 <type>anynonarray
</type> <literal>||
</literal> <type>text
</type>
2485 <returnvalue>text
</returnvalue>
2488 Converts the non-string input to text, then concatenates the two
2489 strings. (The non-string input cannot be of an array type, because
2490 that would create ambiguity with the array
<literal>||
</literal>
2491 operators. If you want to concatenate an array's text equivalent,
2492 cast it to
<type>text
</type> explicitly.)
2495 <literal>'Value: ' ||
42</literal>
2496 <returnvalue>Value:
42</returnvalue>
2501 <entry role=
"func_table_entry"><para role=
"func_signature">
2503 <primary>btrim
</primary>
2505 <function>btrim
</function> (
<parameter>string
</parameter> <type>text
</type>
2506 <optional>,
<parameter>characters
</parameter> <type>text
</type> </optional> )
2507 <returnvalue>text
</returnvalue>
2510 Removes the longest string containing only characters
2511 in
<parameter>characters
</parameter> (a space by default)
2512 from the start and end of
<parameter>string
</parameter>.
2515 <literal>btrim('xyxtrimyyx', 'xyz')
</literal>
2516 <returnvalue>trim
</returnvalue>
2521 <entry role=
"func_table_entry"><para role=
"func_signature">
2523 <primary>normalized
</primary>
2526 <primary>Unicode normalization
</primary>
2528 <type>text
</type> <literal>IS
</literal> <optional><literal>NOT
</literal></optional> <optional><parameter>form
</parameter></optional> <literal>NORMALIZED
</literal>
2529 <returnvalue>boolean
</returnvalue>
2532 Checks whether the string is in the specified Unicode normalization
2533 form. The optional
<parameter>form
</parameter> key word specifies the
2534 form:
<literal>NFC
</literal> (the default),
<literal>NFD
</literal>,
2535 <literal>NFKC
</literal>, or
<literal>NFKD
</literal>. This expression can
2536 only be used when the server encoding is
<literal>UTF8
</literal>. Note
2537 that checking for normalization using this expression is often faster
2538 than normalizing possibly already normalized strings.
2541 <literal>U
&'\
0061\
0308bc' IS NFD NORMALIZED
</literal>
2542 <returnvalue>t
</returnvalue>
2547 <entry role=
"func_table_entry"><para role=
"func_signature">
2549 <primary>bit_length
</primary>
2551 <function>bit_length
</function> (
<type>text
</type> )
2552 <returnvalue>integer
</returnvalue>
2555 Returns number of bits in the string (
8
2556 times the
<function>octet_length
</function>).
2559 <literal>bit_length('jose')
</literal>
2560 <returnvalue>32</returnvalue>
2565 <entry role=
"func_table_entry"><para role=
"func_signature">
2567 <primary>char_length
</primary>
2570 <primary>character string
</primary>
2571 <secondary>length
</secondary>
2574 <primary>length
</primary>
2575 <secondary sortas=
"character string">of a character string
</secondary>
2576 <see>character string, length
</see>
2578 <function>char_length
</function> (
<type>text
</type> )
2579 <returnvalue>integer
</returnvalue>
2581 <para role=
"func_signature">
2583 <primary>character_length
</primary>
2585 <function>character_length
</function> (
<type>text
</type> )
2586 <returnvalue>integer
</returnvalue>
2589 Returns number of characters in the string.
2592 <literal>char_length('jos
é')
</literal>
2593 <returnvalue>4</returnvalue>
2598 <entry role=
"func_table_entry"><para role=
"func_signature">
2600 <primary>lower
</primary>
2602 <function>lower
</function> (
<type>text
</type> )
2603 <returnvalue>text
</returnvalue>
2606 Converts the string to all lower case, according to the rules of the
2610 <literal>lower('TOM')
</literal>
2611 <returnvalue>tom
</returnvalue>
2616 <entry role=
"func_table_entry"><para role=
"func_signature">
2618 <primary>lpad
</primary>
2620 <function>lpad
</function> (
<parameter>string
</parameter> <type>text
</type>,
2621 <parameter>length
</parameter> <type>integer
</type>
2622 <optional>,
<parameter>fill
</parameter> <type>text
</type> </optional> )
2623 <returnvalue>text
</returnvalue>
2626 Extends the
<parameter>string
</parameter> to length
2627 <parameter>length
</parameter> by prepending the characters
2628 <parameter>fill
</parameter> (a space by default). If the
2629 <parameter>string
</parameter> is already longer than
2630 <parameter>length
</parameter> then it is truncated (on the right).
2633 <literal>lpad('hi',
5, 'xy')
</literal>
2634 <returnvalue>xyxhi
</returnvalue>
2639 <entry role=
"func_table_entry"><para role=
"func_signature">
2641 <primary>ltrim
</primary>
2643 <function>ltrim
</function> (
<parameter>string
</parameter> <type>text
</type>
2644 <optional>,
<parameter>characters
</parameter> <type>text
</type> </optional> )
2645 <returnvalue>text
</returnvalue>
2648 Removes the longest string containing only characters in
2649 <parameter>characters
</parameter> (a space by default) from the start of
2650 <parameter>string
</parameter>.
2653 <literal>ltrim('zzzytest', 'xyz')
</literal>
2654 <returnvalue>test
</returnvalue>
2659 <entry role=
"func_table_entry"><para role=
"func_signature">
2661 <primary>normalize
</primary>
2664 <primary>Unicode normalization
</primary>
2666 <function>normalize
</function> (
<type>text
</type>
2667 <optional>,
<parameter>form
</parameter> </optional> )
2668 <returnvalue>text
</returnvalue>
2671 Converts the string to the specified Unicode
2672 normalization form. The optional
<parameter>form
</parameter> key word
2673 specifies the form:
<literal>NFC
</literal> (the default),
2674 <literal>NFD
</literal>,
<literal>NFKC
</literal>, or
2675 <literal>NFKD
</literal>. This function can only be used when the
2676 server encoding is
<literal>UTF8
</literal>.
2679 <literal>normalize(U
&'\
0061\
0308bc', NFC)
</literal>
2680 <returnvalue>U
&'\
00E4bc'
</returnvalue>
2685 <entry role=
"func_table_entry"><para role=
"func_signature">
2687 <primary>octet_length
</primary>
2689 <function>octet_length
</function> (
<type>text
</type> )
2690 <returnvalue>integer
</returnvalue>
2693 Returns number of bytes in the string.
2696 <literal>octet_length('jos
é')
</literal>
2697 <returnvalue>5</returnvalue> (if server encoding is UTF8)
2702 <entry role=
"func_table_entry"><para role=
"func_signature">
2704 <primary>octet_length
</primary>
2706 <function>octet_length
</function> (
<type>character
</type> )
2707 <returnvalue>integer
</returnvalue>
2710 Returns number of bytes in the string. Since this version of the
2711 function accepts type
<type>character
</type> directly, it will not
2712 strip trailing spaces.
2715 <literal>octet_length('abc '::character(
4))
</literal>
2716 <returnvalue>4</returnvalue>
2721 <entry role=
"func_table_entry"><para role=
"func_signature">
2723 <primary>overlay
</primary>
2725 <function>overlay
</function> (
<parameter>string
</parameter> <type>text
</type> <literal>PLACING
</literal> <parameter>newsubstring
</parameter> <type>text
</type> <literal>FROM
</literal> <parameter>start
</parameter> <type>integer
</type> <optional> <literal>FOR
</literal> <parameter>count
</parameter> <type>integer
</type> </optional> )
2726 <returnvalue>text
</returnvalue>
2729 Replaces the substring of
<parameter>string
</parameter> that starts at
2730 the
<parameter>start
</parameter>'th character and extends
2731 for
<parameter>count
</parameter> characters
2732 with
<parameter>newsubstring
</parameter>.
2733 If
<parameter>count
</parameter> is omitted, it defaults to the length
2734 of
<parameter>newsubstring
</parameter>.
2737 <literal>overlay('Txxxxas' placing 'hom' from
2 for
4)
</literal>
2738 <returnvalue>Thomas
</returnvalue>
2743 <entry role=
"func_table_entry"><para role=
"func_signature">
2745 <primary>position
</primary>
2747 <function>position
</function> (
<parameter>substring
</parameter> <type>text
</type> <literal>IN
</literal> <parameter>string
</parameter> <type>text
</type> )
2748 <returnvalue>integer
</returnvalue>
2751 Returns first starting index of the specified
2752 <parameter>substring
</parameter> within
2753 <parameter>string
</parameter>, or zero if it's not present.
2756 <literal>position('om' in 'Thomas')
</literal>
2757 <returnvalue>3</returnvalue>
2762 <entry role=
"func_table_entry"><para role=
"func_signature">
2764 <primary>rpad
</primary>
2766 <function>rpad
</function> (
<parameter>string
</parameter> <type>text
</type>,
2767 <parameter>length
</parameter> <type>integer
</type>
2768 <optional>,
<parameter>fill
</parameter> <type>text
</type> </optional> )
2769 <returnvalue>text
</returnvalue>
2772 Extends the
<parameter>string
</parameter> to length
2773 <parameter>length
</parameter> by appending the characters
2774 <parameter>fill
</parameter> (a space by default). If the
2775 <parameter>string
</parameter> is already longer than
2776 <parameter>length
</parameter> then it is truncated.
2779 <literal>rpad('hi',
5, 'xy')
</literal>
2780 <returnvalue>hixyx
</returnvalue>
2785 <entry role=
"func_table_entry"><para role=
"func_signature">
2787 <primary>rtrim
</primary>
2789 <function>rtrim
</function> (
<parameter>string
</parameter> <type>text
</type>
2790 <optional>,
<parameter>characters
</parameter> <type>text
</type> </optional> )
2791 <returnvalue>text
</returnvalue>
2794 Removes the longest string containing only characters in
2795 <parameter>characters
</parameter> (a space by default) from the end of
2796 <parameter>string
</parameter>.
2799 <literal>rtrim('testxxzx', 'xyz')
</literal>
2800 <returnvalue>test
</returnvalue>
2805 <entry role=
"func_table_entry"><para role=
"func_signature">
2807 <primary>substring
</primary>
2809 <function>substring
</function> (
<parameter>string
</parameter> <type>text
</type> <optional> <literal>FROM
</literal> <parameter>start
</parameter> <type>integer
</type> </optional> <optional> <literal>FOR
</literal> <parameter>count
</parameter> <type>integer
</type> </optional> )
2810 <returnvalue>text
</returnvalue>
2813 Extracts the substring of
<parameter>string
</parameter> starting at
2814 the
<parameter>start
</parameter>'th character if that is specified,
2815 and stopping after
<parameter>count
</parameter> characters if that is
2816 specified. Provide at least one of
<parameter>start
</parameter>
2817 and
<parameter>count
</parameter>.
2820 <literal>substring('Thomas' from
2 for
3)
</literal>
2821 <returnvalue>hom
</returnvalue>
2824 <literal>substring('Thomas' from
3)
</literal>
2825 <returnvalue>omas
</returnvalue>
2828 <literal>substring('Thomas' for
2)
</literal>
2829 <returnvalue>Th
</returnvalue>
2834 <entry role=
"func_table_entry"><para role=
"func_signature">
2835 <function>substring
</function> (
<parameter>string
</parameter> <type>text
</type> <literal>FROM
</literal> <parameter>pattern
</parameter> <type>text
</type> )
2836 <returnvalue>text
</returnvalue>
2839 Extracts the first substring matching POSIX regular expression; see
2840 <xref linkend=
"functions-posix-regexp"/>.
2843 <literal>substring('Thomas' from '...$')
</literal>
2844 <returnvalue>mas
</returnvalue>
2849 <entry role=
"func_table_entry"><para role=
"func_signature">
2850 <function>substring
</function> (
<parameter>string
</parameter> <type>text
</type> <literal>SIMILAR
</literal> <parameter>pattern
</parameter> <type>text
</type> <literal>ESCAPE
</literal> <parameter>escape
</parameter> <type>text
</type> )
2851 <returnvalue>text
</returnvalue>
2853 <para role=
"func_signature">
2854 <function>substring
</function> (
<parameter>string
</parameter> <type>text
</type> <literal>FROM
</literal> <parameter>pattern
</parameter> <type>text
</type> <literal>FOR
</literal> <parameter>escape
</parameter> <type>text
</type> )
2855 <returnvalue>text
</returnvalue>
2858 Extracts the first substring matching
<acronym>SQL
</acronym> regular expression;
2859 see
<xref linkend=
"functions-similarto-regexp"/>. The first form has
2860 been specified since SQL:
2003; the second form was only in SQL:
1999
2861 and should be considered obsolete.
2864 <literal>substring('Thomas' similar '%#
"o_a#"_' escape '#')
</literal>
2865 <returnvalue>oma
</returnvalue>
2870 <entry role=
"func_table_entry"><para role=
"func_signature">
2872 <primary>trim
</primary>
2874 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional>
2875 <optional> <parameter>characters
</parameter> <type>text
</type> </optional> <literal>FROM
</literal>
2876 <parameter>string
</parameter> <type>text
</type> )
2877 <returnvalue>text
</returnvalue>
2880 Removes the longest string containing only characters in
2881 <parameter>characters
</parameter> (a space by default) from the
2882 start, end, or both ends (
<literal>BOTH
</literal> is the default)
2883 of
<parameter>string
</parameter>.
2886 <literal>trim(both 'xyz' from 'yxTomxx')
</literal>
2887 <returnvalue>Tom
</returnvalue>
2892 <entry role=
"func_table_entry"><para role=
"func_signature">
2893 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional> <optional> <literal>FROM
</literal> </optional>
2894 <parameter>string
</parameter> <type>text
</type> <optional>,
2895 <parameter>characters
</parameter> <type>text
</type> </optional> )
2896 <returnvalue>text
</returnvalue>
2899 This is a non-standard syntax for
<function>trim()
</function>.
2902 <literal>trim(both from 'yxTomxx', 'xyz')
</literal>
2903 <returnvalue>Tom
</returnvalue>
2908 <entry role=
"func_table_entry"><para role=
"func_signature">
2910 <primary>unicode_assigned
</primary>
2912 <function>unicode_assigned
</function> (
<type>text
</type> )
2913 <returnvalue>boolean
</returnvalue>
2916 Returns
<literal>true
</literal> if all characters in the string are
2917 assigned Unicode codepoints;
<literal>false
</literal> otherwise. This
2918 function can only be used when the server encoding is
2919 <literal>UTF8
</literal>.
2924 <entry role=
"func_table_entry"><para role=
"func_signature">
2926 <primary>upper
</primary>
2928 <function>upper
</function> (
<type>text
</type> )
2929 <returnvalue>text
</returnvalue>
2932 Converts the string to all upper case, according to the rules of the
2936 <literal>upper('tom')
</literal>
2937 <returnvalue>TOM
</returnvalue>
2945 Additional string manipulation functions and operators are available
2946 and are listed in
<xref linkend=
"functions-string-other"/>. (Some of
2947 these are used internally to implement
2948 the
<acronym>SQL
</acronym>-standard string functions listed in
2949 <xref linkend=
"functions-string-sql"/>.)
2950 There are also pattern-matching operators, which are described in
2951 <xref linkend=
"functions-matching"/>, and operators for full-text
2952 search, which are described in
<xref linkend=
"textsearch"/>.
2955 <table id=
"functions-string-other">
2956 <title>Other String Functions and Operators
</title>
2960 <entry role=
"func_table_entry"><para role=
"func_signature">
2974 <entry role=
"func_table_entry"><para role=
"func_signature">
2976 <primary>character string
</primary>
2977 <secondary>prefix test
</secondary>
2979 <type>text
</type> <literal>^@
</literal> <type>text
</type>
2980 <returnvalue>boolean
</returnvalue>
2983 Returns true if the first string starts with the second string
2984 (equivalent to the
<function>starts_with()
</function> function).
2987 <literal>'alphabet' ^@ 'alph'
</literal>
2988 <returnvalue>t
</returnvalue>
2993 <entry role=
"func_table_entry"><para role=
"func_signature">
2995 <primary>ascii
</primary>
2997 <function>ascii
</function> (
<type>text
</type> )
2998 <returnvalue>integer
</returnvalue>
3001 Returns the numeric code of the first character of the argument.
3002 In
<acronym>UTF8
</acronym> encoding, returns the Unicode code point
3003 of the character. In other multibyte encodings, the argument must
3004 be an
<acronym>ASCII
</acronym> character.
3007 <literal>ascii('x')
</literal>
3008 <returnvalue>120</returnvalue>
3013 <entry role=
"func_table_entry"><para role=
"func_signature">
3015 <primary>chr
</primary>
3017 <function>chr
</function> (
<type>integer
</type> )
3018 <returnvalue>text
</returnvalue>
3021 Returns the character with the given code. In
<acronym>UTF8
</acronym>
3022 encoding the argument is treated as a Unicode code point. In other
3023 multibyte encodings the argument must designate
3024 an
<acronym>ASCII
</acronym> character.
<literal>chr(
0)
</literal> is
3025 disallowed because text data types cannot store that character.
3028 <literal>chr(
65)
</literal>
3029 <returnvalue>A
</returnvalue>
3034 <entry role=
"func_table_entry"><para role=
"func_signature">
3036 <primary>concat
</primary>
3038 <function>concat
</function> (
<parameter>val1
</parameter> <type>"any"</type>
3039 [,
<parameter>val2
</parameter> <type>"any"</type> [, ...] ] )
3040 <returnvalue>text
</returnvalue>
3043 Concatenates the text representations of all the arguments.
3044 NULL arguments are ignored.
3047 <literal>concat('abcde',
2, NULL,
22)
</literal>
3048 <returnvalue>abcde222
</returnvalue>
3053 <entry role=
"func_table_entry"><para role=
"func_signature">
3055 <primary>concat_ws
</primary>
3057 <function>concat_ws
</function> (
<parameter>sep
</parameter> <type>text
</type>,
3058 <parameter>val1
</parameter> <type>"any"</type>
3059 [,
<parameter>val2
</parameter> <type>"any"</type> [, ...] ] )
3060 <returnvalue>text
</returnvalue>
3063 Concatenates all but the first argument, with separators. The first
3064 argument is used as the separator string, and should not be NULL.
3065 Other NULL arguments are ignored.
3068 <literal>concat_ws(',', 'abcde',
2, NULL,
22)
</literal>
3069 <returnvalue>abcde,
2,
22</returnvalue>
3074 <entry role=
"func_table_entry"><para role=
"func_signature">
3076 <primary>format
</primary>
3078 <function>format
</function> (
<parameter>formatstr
</parameter> <type>text
</type>
3079 [,
<parameter>formatarg
</parameter> <type>"any"</type> [, ...] ] )
3080 <returnvalue>text
</returnvalue>
3083 Formats arguments according to a format string;
3084 see
<xref linkend=
"functions-string-format"/>.
3085 This function is similar to the C function
<function>sprintf
</function>.
3088 <literal>format('Hello %s, %
1$s', 'World')
</literal>
3089 <returnvalue>Hello World, World
</returnvalue>
3094 <entry role=
"func_table_entry"><para role=
"func_signature">
3096 <primary>initcap
</primary>
3098 <function>initcap
</function> (
<type>text
</type> )
3099 <returnvalue>text
</returnvalue>
3102 Converts the first letter of each word to upper case and the
3103 rest to lower case. Words are sequences of alphanumeric
3104 characters separated by non-alphanumeric characters.
3107 <literal>initcap('hi THOMAS')
</literal>
3108 <returnvalue>Hi Thomas
</returnvalue>
3113 <entry role=
"func_table_entry"><para role=
"func_signature">
3115 <primary>left
</primary>
3117 <function>left
</function> (
<parameter>string
</parameter> <type>text
</type>,
3118 <parameter>n
</parameter> <type>integer
</type> )
3119 <returnvalue>text
</returnvalue>
3122 Returns first
<parameter>n
</parameter> characters in the
3123 string, or when
<parameter>n
</parameter> is negative, returns
3124 all but last |
<parameter>n
</parameter>| characters.
3127 <literal>left('abcde',
2)
</literal>
3128 <returnvalue>ab
</returnvalue>
3133 <entry role=
"func_table_entry"><para role=
"func_signature">
3135 <primary>length
</primary>
3137 <function>length
</function> (
<type>text
</type> )
3138 <returnvalue>integer
</returnvalue>
3141 Returns the number of characters in the string.
3144 <literal>length('jose')
</literal>
3145 <returnvalue>4</returnvalue>
3150 <entry role=
"func_table_entry"><para role=
"func_signature">
3152 <primary>md5
</primary>
3154 <function>md5
</function> (
<type>text
</type> )
3155 <returnvalue>text
</returnvalue>
3158 Computes the MD5
<link linkend=
"functions-hash-note">hash
</link> of
3159 the argument, with the result written in hexadecimal.
3162 <literal>md5('abc')
</literal>
3163 <returnvalue>900150983cd24fb0
&zwsp;d6963f7d28e17f72
</returnvalue>
3168 <entry role=
"func_table_entry"><para role=
"func_signature">
3170 <primary>parse_ident
</primary>
3172 <function>parse_ident
</function> (
<parameter>qualified_identifier
</parameter> <type>text
</type>
3173 [,
<parameter>strict_mode
</parameter> <type>boolean
</type> <literal>DEFAULT
</literal> <literal>true
</literal> ] )
3174 <returnvalue>text[]
</returnvalue>
3177 Splits
<parameter>qualified_identifier
</parameter> into an array of
3178 identifiers, removing any quoting of individual identifiers. By
3179 default, extra characters after the last identifier are considered an
3180 error; but if the second parameter is
<literal>false
</literal>, then such
3181 extra characters are ignored. (This behavior is useful for parsing
3182 names for objects like functions.) Note that this function does not
3183 truncate over-length identifiers. If you want truncation you can cast
3184 the result to
<type>name[]
</type>.
3187 <literal>parse_ident('
"SomeSchema".someTable')
</literal>
3188 <returnvalue>{SomeSchema,sometable}
</returnvalue>
3193 <entry role=
"func_table_entry"><para role=
"func_signature">
3195 <primary>pg_client_encoding
</primary>
3197 <function>pg_client_encoding
</function> ( )
3198 <returnvalue>name
</returnvalue>
3201 Returns current client encoding name.
3204 <literal>pg_client_encoding()
</literal>
3205 <returnvalue>UTF8
</returnvalue>
3210 <entry role=
"func_table_entry"><para role=
"func_signature">
3212 <primary>quote_ident
</primary>
3214 <function>quote_ident
</function> (
<type>text
</type> )
3215 <returnvalue>text
</returnvalue>
3218 Returns the given string suitably quoted to be used as an identifier
3219 in an
<acronym>SQL
</acronym> statement string.
3220 Quotes are added only if necessary (i.e., if the string contains
3221 non-identifier characters or would be case-folded).
3222 Embedded quotes are properly doubled.
3223 See also
<xref linkend=
"plpgsql-quote-literal-example"/>.
3226 <literal>quote_ident('Foo bar')
</literal>
3227 <returnvalue>"Foo bar"</returnvalue>
3232 <entry role=
"func_table_entry"><para role=
"func_signature">
3234 <primary>quote_literal
</primary>
3236 <function>quote_literal
</function> (
<type>text
</type> )
3237 <returnvalue>text
</returnvalue>
3240 Returns the given string suitably quoted to be used as a string literal
3241 in an
<acronym>SQL
</acronym> statement string.
3242 Embedded single-quotes and backslashes are properly doubled.
3243 Note that
<function>quote_literal
</function> returns null on null
3244 input; if the argument might be null,
3245 <function>quote_nullable
</function> is often more suitable.
3246 See also
<xref linkend=
"plpgsql-quote-literal-example"/>.
3249 <literal>quote_literal(E'O\'Reilly')
</literal>
3250 <returnvalue>'O''Reilly'
</returnvalue>
3255 <entry role=
"func_table_entry"><para role=
"func_signature">
3256 <function>quote_literal
</function> (
<type>anyelement
</type> )
3257 <returnvalue>text
</returnvalue>
3260 Converts the given value to text and then quotes it as a literal.
3261 Embedded single-quotes and backslashes are properly doubled.
3264 <literal>quote_literal(
42.5)
</literal>
3265 <returnvalue>'
42.5'
</returnvalue>
3270 <entry role=
"func_table_entry"><para role=
"func_signature">
3272 <primary>quote_nullable
</primary>
3274 <function>quote_nullable
</function> (
<type>text
</type> )
3275 <returnvalue>text
</returnvalue>
3278 Returns the given string suitably quoted to be used as a string literal
3279 in an
<acronym>SQL
</acronym> statement string; or, if the argument
3280 is null, returns
<literal>NULL
</literal>.
3281 Embedded single-quotes and backslashes are properly doubled.
3282 See also
<xref linkend=
"plpgsql-quote-literal-example"/>.
3285 <literal>quote_nullable(NULL)
</literal>
3286 <returnvalue>NULL
</returnvalue>
3291 <entry role=
"func_table_entry"><para role=
"func_signature">
3292 <function>quote_nullable
</function> (
<type>anyelement
</type> )
3293 <returnvalue>text
</returnvalue>
3296 Converts the given value to text and then quotes it as a literal;
3297 or, if the argument is null, returns
<literal>NULL
</literal>.
3298 Embedded single-quotes and backslashes are properly doubled.
3301 <literal>quote_nullable(
42.5)
</literal>
3302 <returnvalue>'
42.5'
</returnvalue>
3307 <entry role=
"func_table_entry"><para role=
"func_signature">
3309 <primary>regexp_count
</primary>
3311 <function>regexp_count
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3312 [,
<parameter>start
</parameter> <type>integer
</type>
3313 [,
<parameter>flags
</parameter> <type>text
</type> ] ] )
3314 <returnvalue>integer
</returnvalue>
3317 Returns the number of times the POSIX regular
3318 expression
<parameter>pattern
</parameter> matches in
3319 the
<parameter>string
</parameter>; see
3320 <xref linkend=
"functions-posix-regexp"/>.
3323 <literal>regexp_count('
123456789012', '\d\d\d',
2)
</literal>
3324 <returnvalue>3</returnvalue>
3329 <entry role=
"func_table_entry"><para role=
"func_signature">
3331 <primary>regexp_instr
</primary>
3333 <function>regexp_instr
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3334 [,
<parameter>start
</parameter> <type>integer
</type>
3335 [,
<parameter>N
</parameter> <type>integer
</type>
3336 [,
<parameter>endoption
</parameter> <type>integer
</type>
3337 [,
<parameter>flags
</parameter> <type>text
</type>
3338 [,
<parameter>subexpr
</parameter> <type>integer
</type> ] ] ] ] ] )
3339 <returnvalue>integer
</returnvalue>
3342 Returns the position within
<parameter>string
</parameter> where
3343 the
<parameter>N
</parameter>'th match of the POSIX regular
3344 expression
<parameter>pattern
</parameter> occurs, or zero if there is
3345 no such match; see
<xref linkend=
"functions-posix-regexp"/>.
3348 <literal>regexp_instr('ABCDEF', 'c(.)(..)',
1,
1,
0, 'i')
</literal>
3349 <returnvalue>3</returnvalue>
3352 <literal>regexp_instr('ABCDEF', 'c(.)(..)',
1,
1,
0, 'i',
2)
</literal>
3353 <returnvalue>5</returnvalue>
3358 <entry role=
"func_table_entry"><para role=
"func_signature">
3360 <primary>regexp_like
</primary>
3362 <function>regexp_like
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3363 [,
<parameter>flags
</parameter> <type>text
</type> ] )
3364 <returnvalue>boolean
</returnvalue>
3367 Checks whether a match of the POSIX regular
3368 expression
<parameter>pattern
</parameter> occurs
3369 within
<parameter>string
</parameter>; see
3370 <xref linkend=
"functions-posix-regexp"/>.
3373 <literal>regexp_like('Hello World', 'world$', 'i')
</literal>
3374 <returnvalue>t
</returnvalue>
3379 <entry role=
"func_table_entry"><para role=
"func_signature">
3381 <primary>regexp_match
</primary>
3383 <function>regexp_match
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3384 <returnvalue>text[]
</returnvalue>
3387 Returns substrings within the first match of the POSIX regular
3388 expression
<parameter>pattern
</parameter> to
3389 the
<parameter>string
</parameter>; see
3390 <xref linkend=
"functions-posix-regexp"/>.
3393 <literal>regexp_match('foobarbequebaz', '(bar)(beque)')
</literal>
3394 <returnvalue>{bar,beque}
</returnvalue>
3399 <entry role=
"func_table_entry"><para role=
"func_signature">
3401 <primary>regexp_matches
</primary>
3403 <function>regexp_matches
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3404 <returnvalue>setof text[]
</returnvalue>
3407 Returns substrings within the first match of the POSIX regular
3408 expression
<parameter>pattern
</parameter> to
3409 the
<parameter>string
</parameter>, or substrings within all
3410 such matches if the
<literal>g
</literal> flag is used;
3411 see
<xref linkend=
"functions-posix-regexp"/>.
3414 <literal>regexp_matches('foobarbequebaz', 'ba.', 'g')
</literal>
3415 <returnvalue></returnvalue>
3424 <entry role=
"func_table_entry"><para role=
"func_signature">
3426 <primary>regexp_replace
</primary>
3428 <function>regexp_replace
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>,
<parameter>replacement
</parameter> <type>text
</type>
3429 <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> )
3430 <returnvalue>text
</returnvalue>
3433 Replaces the substring that is the first match to the POSIX
3434 regular expression
<parameter>pattern
</parameter>, or all such
3435 matches if the
<literal>g
</literal> flag is used; see
3436 <xref linkend=
"functions-posix-regexp"/>.
3439 <literal>regexp_replace('Thomas', '.[mN]a.', 'M')
</literal>
3440 <returnvalue>ThM
</returnvalue>
3445 <entry role=
"func_table_entry"><para role=
"func_signature">
3446 <function>regexp_replace
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>,
<parameter>replacement
</parameter> <type>text
</type>,
3447 <parameter>start
</parameter> <type>integer
</type>
3448 <optional>,
<parameter>N
</parameter> <type>integer
</type>
3449 <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> </optional> )
3450 <returnvalue>text
</returnvalue>
3453 Replaces the substring that is the
<parameter>N
</parameter>'th
3454 match to the POSIX regular expression
<parameter>pattern
</parameter>,
3455 or all such matches if
<parameter>N
</parameter> is zero, with the
3456 search beginning at the
<parameter>start
</parameter>'th character
3457 of
<parameter>string
</parameter>. If
<parameter>N
</parameter> is
3458 omitted, it defaults to
1. See
3459 <xref linkend=
"functions-posix-regexp"/>.
3462 <literal>regexp_replace('Thomas', '.', 'X',
3,
2)
</literal>
3463 <returnvalue>ThoXas
</returnvalue>
3466 <literal>regexp_replace(string=
>'hello world', pattern=
>'l', replacement=
>'XX', start=
>1,
"N"=
>2)
</literal>
3467 <returnvalue>helXXo world
</returnvalue>
3472 <entry role=
"func_table_entry"><para role=
"func_signature">
3474 <primary>regexp_split_to_array
</primary>
3476 <function>regexp_split_to_array
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3477 <returnvalue>text[]
</returnvalue>
3480 Splits
<parameter>string
</parameter> using a POSIX regular
3481 expression as the delimiter, producing an array of results; see
3482 <xref linkend=
"functions-posix-regexp"/>.
3485 <literal>regexp_split_to_array('hello world', '\s+')
</literal>
3486 <returnvalue>{hello,world}
</returnvalue>
3491 <entry role=
"func_table_entry"><para role=
"func_signature">
3493 <primary>regexp_split_to_table
</primary>
3495 <function>regexp_split_to_table
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3496 <returnvalue>setof text
</returnvalue>
3499 Splits
<parameter>string
</parameter> using a POSIX regular
3500 expression as the delimiter, producing a set of results; see
3501 <xref linkend=
"functions-posix-regexp"/>.
3504 <literal>regexp_split_to_table('hello world', '\s+')
</literal>
3505 <returnvalue></returnvalue>
3514 <entry role=
"func_table_entry"><para role=
"func_signature">
3516 <primary>regexp_substr
</primary>
3518 <function>regexp_substr
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3519 [,
<parameter>start
</parameter> <type>integer
</type>
3520 [,
<parameter>N
</parameter> <type>integer
</type>
3521 [,
<parameter>flags
</parameter> <type>text
</type>
3522 [,
<parameter>subexpr
</parameter> <type>integer
</type> ] ] ] ] )
3523 <returnvalue>text
</returnvalue>
3526 Returns the substring within
<parameter>string
</parameter> that
3527 matches the
<parameter>N
</parameter>'th occurrence of the POSIX
3528 regular expression
<parameter>pattern
</parameter>,
3529 or
<literal>NULL
</literal> if there is no such match; see
3530 <xref linkend=
"functions-posix-regexp"/>.
3533 <literal>regexp_substr('ABCDEF', 'c(.)(..)',
1,
1, 'i')
</literal>
3534 <returnvalue>CDEF
</returnvalue>
3537 <literal>regexp_substr('ABCDEF', 'c(.)(..)',
1,
1, 'i',
2)
</literal>
3538 <returnvalue>EF
</returnvalue>
3543 <entry role=
"func_table_entry"><para role=
"func_signature">
3545 <primary>repeat
</primary>
3547 <function>repeat
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>number
</parameter> <type>integer
</type> )
3548 <returnvalue>text
</returnvalue>
3551 Repeats
<parameter>string
</parameter> the specified
3552 <parameter>number
</parameter> of times.
3555 <literal>repeat('Pg',
4)
</literal>
3556 <returnvalue>PgPgPgPg
</returnvalue>
3561 <entry role=
"func_table_entry"><para role=
"func_signature">
3563 <primary>replace
</primary>
3565 <function>replace
</function> (
<parameter>string
</parameter> <type>text
</type>,
3566 <parameter>from
</parameter> <type>text
</type>,
3567 <parameter>to
</parameter> <type>text
</type> )
3568 <returnvalue>text
</returnvalue>
3571 Replaces all occurrences in
<parameter>string
</parameter> of
3572 substring
<parameter>from
</parameter> with
3573 substring
<parameter>to
</parameter>.
3576 <literal>replace('abcdefabcdef', 'cd', 'XX')
</literal>
3577 <returnvalue>abXXefabXXef
</returnvalue>
3582 <entry role=
"func_table_entry"><para role=
"func_signature">
3584 <primary>reverse
</primary>
3586 <function>reverse
</function> (
<type>text
</type> )
3587 <returnvalue>text
</returnvalue>
3590 Reverses the order of the characters in the string.
3593 <literal>reverse('abcde')
</literal>
3594 <returnvalue>edcba
</returnvalue>
3599 <entry role=
"func_table_entry"><para role=
"func_signature">
3601 <primary>right
</primary>
3603 <function>right
</function> (
<parameter>string
</parameter> <type>text
</type>,
3604 <parameter>n
</parameter> <type>integer
</type> )
3605 <returnvalue>text
</returnvalue>
3608 Returns last
<parameter>n
</parameter> characters in the string,
3609 or when
<parameter>n
</parameter> is negative, returns all but
3610 first |
<parameter>n
</parameter>| characters.
3613 <literal>right('abcde',
2)
</literal>
3614 <returnvalue>de
</returnvalue>
3619 <entry role=
"func_table_entry"><para role=
"func_signature">
3621 <primary>split_part
</primary>
3623 <function>split_part
</function> (
<parameter>string
</parameter> <type>text
</type>,
3624 <parameter>delimiter
</parameter> <type>text
</type>,
3625 <parameter>n
</parameter> <type>integer
</type> )
3626 <returnvalue>text
</returnvalue>
3629 Splits
<parameter>string
</parameter> at occurrences
3630 of
<parameter>delimiter
</parameter> and returns
3631 the
<parameter>n
</parameter>'th field (counting from one),
3632 or when
<parameter>n
</parameter> is negative, returns
3633 the |
<parameter>n
</parameter>|'th-from-last field.
3636 <literal>split_part('abc~@~def~@~ghi', '~@~',
2)
</literal>
3637 <returnvalue>def
</returnvalue>
3640 <literal>split_part('abc,def,ghi,jkl', ',', -
2)
</literal>
3641 <returnvalue>ghi
</returnvalue>
3646 <entry role=
"func_table_entry"><para role=
"func_signature">
3648 <primary>starts_with
</primary>
3650 <function>starts_with
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>prefix
</parameter> <type>text
</type> )
3651 <returnvalue>boolean
</returnvalue>
3654 Returns true if
<parameter>string
</parameter> starts
3655 with
<parameter>prefix
</parameter>.
3658 <literal>starts_with('alphabet', 'alph')
</literal>
3659 <returnvalue>t
</returnvalue>
3664 <entry role=
"func_table_entry"><para role=
"func_signature">
3665 <indexterm id=
"function-string-to-array">
3666 <primary>string_to_array
</primary>
3668 <function>string_to_array
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>delimiter
</parameter> <type>text
</type> <optional>,
<parameter>null_string
</parameter> <type>text
</type> </optional> )
3669 <returnvalue>text[]
</returnvalue>
3672 Splits the
<parameter>string
</parameter> at occurrences
3673 of
<parameter>delimiter
</parameter> and forms the resulting fields
3674 into a
<type>text
</type> array.
3675 If
<parameter>delimiter
</parameter> is
<literal>NULL
</literal>,
3676 each character in the
<parameter>string
</parameter> will become a
3677 separate element in the array.
3678 If
<parameter>delimiter
</parameter> is an empty string, then
3679 the
<parameter>string
</parameter> is treated as a single field.
3680 If
<parameter>null_string
</parameter> is supplied and is
3681 not
<literal>NULL
</literal>, fields matching that string are
3682 replaced by
<literal>NULL
</literal>.
3683 See also
<link linkend=
"function-array-to-string"><function>array_to_string
</function></link>.
3686 <literal>string_to_array('xx~~yy~~zz', '~~', 'yy')
</literal>
3687 <returnvalue>{xx,NULL,zz}
</returnvalue>
3692 <entry role=
"func_table_entry"><para role=
"func_signature">
3694 <primary>string_to_table
</primary>
3696 <function>string_to_table
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>delimiter
</parameter> <type>text
</type> <optional>,
<parameter>null_string
</parameter> <type>text
</type> </optional> )
3697 <returnvalue>setof text
</returnvalue>
3700 Splits the
<parameter>string
</parameter> at occurrences
3701 of
<parameter>delimiter
</parameter> and returns the resulting fields
3702 as a set of
<type>text
</type> rows.
3703 If
<parameter>delimiter
</parameter> is
<literal>NULL
</literal>,
3704 each character in the
<parameter>string
</parameter> will become a
3705 separate row of the result.
3706 If
<parameter>delimiter
</parameter> is an empty string, then
3707 the
<parameter>string
</parameter> is treated as a single field.
3708 If
<parameter>null_string
</parameter> is supplied and is
3709 not
<literal>NULL
</literal>, fields matching that string are
3710 replaced by
<literal>NULL
</literal>.
3713 <literal>string_to_table('xx~^~yy~^~zz', '~^~', 'yy')
</literal>
3714 <returnvalue></returnvalue>
3724 <entry role=
"func_table_entry"><para role=
"func_signature">
3726 <primary>strpos
</primary>
3728 <function>strpos
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>substring
</parameter> <type>text
</type> )
3729 <returnvalue>integer
</returnvalue>
3732 Returns first starting index of the specified
<parameter>substring
</parameter>
3733 within
<parameter>string
</parameter>, or zero if it's not present.
3734 (Same as
<literal>position(
<parameter>substring
</parameter> in
3735 <parameter>string
</parameter>)
</literal>, but note the reversed
3739 <literal>strpos('high', 'ig')
</literal>
3740 <returnvalue>2</returnvalue>
3745 <entry role=
"func_table_entry"><para role=
"func_signature">
3747 <primary>substr
</primary>
3749 <function>substr
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>start
</parameter> <type>integer
</type> <optional>,
<parameter>count
</parameter> <type>integer
</type> </optional> )
3750 <returnvalue>text
</returnvalue>
3753 Extracts the substring of
<parameter>string
</parameter> starting at
3754 the
<parameter>start
</parameter>'th character,
3755 and extending for
<parameter>count
</parameter> characters if that is
3757 as
<literal>substring(
<parameter>string
</parameter>
3758 from
<parameter>start
</parameter>
3759 for
<parameter>count
</parameter>)
</literal>.)
3762 <literal>substr('alphabet',
3)
</literal>
3763 <returnvalue>phabet
</returnvalue>
3766 <literal>substr('alphabet',
3,
2)
</literal>
3767 <returnvalue>ph
</returnvalue>
3772 <entry role=
"func_table_entry"><para role=
"func_signature">
3774 <primary>to_ascii
</primary>
3776 <function>to_ascii
</function> (
<parameter>string
</parameter> <type>text
</type> )
3777 <returnvalue>text
</returnvalue>
3779 <para role=
"func_signature">
3780 <function>to_ascii
</function> (
<parameter>string
</parameter> <type>text
</type>,
3781 <parameter>encoding
</parameter> <type>name
</type> )
3782 <returnvalue>text
</returnvalue>
3784 <para role=
"func_signature">
3785 <function>to_ascii
</function> (
<parameter>string
</parameter> <type>text
</type>,
3786 <parameter>encoding
</parameter> <type>integer
</type> )
3787 <returnvalue>text
</returnvalue>
3790 Converts
<parameter>string
</parameter> to
<acronym>ASCII
</acronym>
3791 from another encoding, which may be identified by name or number.
3792 If
<parameter>encoding
</parameter> is omitted the database encoding
3793 is assumed (which in practice is the only useful case).
3794 The conversion consists primarily of dropping accents.
3795 Conversion is only supported
3796 from
<literal>LATIN1
</literal>,
<literal>LATIN2
</literal>,
3797 <literal>LATIN9
</literal>, and
<literal>WIN1250
</literal> encodings.
3798 (See the
<xref linkend=
"unaccent"/> module for another, more flexible
3802 <literal>to_ascii('Kar
él')
</literal>
3803 <returnvalue>Karel
</returnvalue>
3808 <entry role=
"func_table_entry"><para role=
"func_signature">
3810 <primary>to_bin
</primary>
3812 <function>to_bin
</function> (
<type>integer
</type> )
3813 <returnvalue>text
</returnvalue>
3815 <para role=
"func_signature">
3816 <function>to_bin
</function> (
<type>bigint
</type> )
3817 <returnvalue>text
</returnvalue>
3820 Converts the number to its equivalent two's complement binary
3824 <literal>to_bin(
2147483647)
</literal>
3825 <returnvalue>1111111111111111111111111111111</returnvalue>
3828 <literal>to_bin(-
1234)
</literal>
3829 <returnvalue>11111111111111111111101100101110</returnvalue>
3834 <entry role=
"func_table_entry"><para role=
"func_signature">
3836 <primary>to_hex
</primary>
3838 <function>to_hex
</function> (
<type>integer
</type> )
3839 <returnvalue>text
</returnvalue>
3841 <para role=
"func_signature">
3842 <function>to_hex
</function> (
<type>bigint
</type> )
3843 <returnvalue>text
</returnvalue>
3846 Converts the number to its equivalent two's complement hexadecimal
3850 <literal>to_hex(
2147483647)
</literal>
3851 <returnvalue>7fffffff
</returnvalue>
3854 <literal>to_hex(-
1234)
</literal>
3855 <returnvalue>fffffb2e
</returnvalue>
3860 <entry role=
"func_table_entry"><para role=
"func_signature">
3862 <primary>to_oct
</primary>
3864 <function>to_oct
</function> (
<type>integer
</type> )
3865 <returnvalue>text
</returnvalue>
3867 <para role=
"func_signature">
3868 <function>to_oct
</function> (
<type>bigint
</type> )
3869 <returnvalue>text
</returnvalue>
3872 Converts the number to its equivalent two's complement octal
3876 <literal>to_oct(
2147483647)
</literal>
3877 <returnvalue>17777777777</returnvalue>
3880 <literal>to_oct(-
1234)
</literal>
3881 <returnvalue>37777775456</returnvalue>
3886 <entry role=
"func_table_entry"><para role=
"func_signature">
3888 <primary>translate
</primary>
3890 <function>translate
</function> (
<parameter>string
</parameter> <type>text
</type>,
3891 <parameter>from
</parameter> <type>text
</type>,
3892 <parameter>to
</parameter> <type>text
</type> )
3893 <returnvalue>text
</returnvalue>
3896 Replaces each character in
<parameter>string
</parameter> that
3897 matches a character in the
<parameter>from
</parameter> set with the
3898 corresponding character in the
<parameter>to
</parameter>
3899 set. If
<parameter>from
</parameter> is longer than
3900 <parameter>to
</parameter>, occurrences of the extra characters in
3901 <parameter>from
</parameter> are deleted.
3904 <literal>translate('
12345', '
143', 'ax')
</literal>
3905 <returnvalue>a2x5
</returnvalue>
3910 <entry role=
"func_table_entry"><para role=
"func_signature">
3912 <primary>unistr
</primary>
3914 <function>unistr
</function> (
<type>text
</type> )
3915 <returnvalue>text
</returnvalue>
3918 Evaluate escaped Unicode characters in the argument. Unicode characters
3920 <literal>\
<replaceable>XXXX
</replaceable></literal> (
4 hexadecimal
3921 digits),
<literal>\+
<replaceable>XXXXXX
</replaceable></literal> (
6
3922 hexadecimal digits),
3923 <literal>\u
<replaceable>XXXX
</replaceable></literal> (
4 hexadecimal
3924 digits), or
<literal>\U
<replaceable>XXXXXXXX
</replaceable></literal>
3925 (
8 hexadecimal digits). To specify a backslash, write two
3926 backslashes. All other characters are taken literally.
3930 If the server encoding is not UTF-
8, the Unicode code point identified
3931 by one of these escape sequences is converted to the actual server
3932 encoding; an error is reported if that's not possible.
3936 This function provides a (non-standard) alternative to string
3937 constants with Unicode escapes (see
<xref
3938 linkend=
"sql-syntax-strings-uescape"/>).
3942 <literal>unistr('d\
0061t\+
000061')
</literal>
3943 <returnvalue>data
</returnvalue>
3946 <literal>unistr('d\u0061t\U00000061')
</literal>
3947 <returnvalue>data
</returnvalue>
3956 The
<function>concat
</function>,
<function>concat_ws
</function> and
3957 <function>format
</function> functions are variadic, so it is possible to
3958 pass the values to be concatenated or formatted as an array marked with
3959 the
<literal>VARIADIC
</literal> keyword (see
<xref
3960 linkend=
"xfunc-sql-variadic-functions"/>). The array's elements are
3961 treated as if they were separate ordinary arguments to the function.
3962 If the variadic array argument is NULL,
<function>concat
</function>
3963 and
<function>concat_ws
</function> return NULL, but
3964 <function>format
</function> treats a NULL as a zero-element array.
3968 See also the aggregate function
<function>string_agg
</function> in
3969 <xref linkend=
"functions-aggregate"/>, and the functions for
3970 converting between strings and the
<type>bytea
</type> type in
3971 <xref linkend=
"functions-binarystring-conversions"/>.
3974 <sect2 id=
"functions-string-format">
3975 <title><function>format
</function></title>
3978 <primary>format
</primary>
3982 The function
<function>format
</function> produces output formatted according to
3983 a format string, in a style similar to the C function
3984 <function>sprintf
</function>.
3989 <function>format
</function>(
<parameter>formatstr
</parameter> <type>text
</type> [,
<parameter>formatarg
</parameter> <type>"any"</type> [, ...] ])
3991 <parameter>formatstr
</parameter> is a format string that specifies how the
3992 result should be formatted. Text in the format string is copied
3993 directly to the result, except where
<firstterm>format specifiers
</firstterm> are
3994 used. Format specifiers act as placeholders in the string, defining how
3995 subsequent function arguments should be formatted and inserted into the
3996 result. Each
<parameter>formatarg
</parameter> argument is converted to text
3997 according to the usual output rules for its data type, and then formatted
3998 and inserted into the result string according to the format specifier(s).
4002 Format specifiers are introduced by a
<literal>%
</literal> character and have
4005 %[
<parameter>position
</parameter>][
<parameter>flags
</parameter>][
<parameter>width
</parameter>]
<parameter>type
</parameter>
4007 where the component fields are:
4011 <term><parameter>position
</parameter> (optional)
</term>
4014 A string of the form
<literal><parameter>n
</parameter>$
</literal> where
4015 <parameter>n
</parameter> is the index of the argument to print.
4016 Index
1 means the first argument after
4017 <parameter>formatstr
</parameter>. If the
<parameter>position
</parameter> is
4018 omitted, the default is to use the next argument in sequence.
4024 <term><parameter>flags
</parameter> (optional)
</term>
4027 Additional options controlling how the format specifier's output is
4028 formatted. Currently the only supported flag is a minus sign
4029 (
<literal>-
</literal>) which will cause the format specifier's output to be
4030 left-justified. This has no effect unless the
<parameter>width
</parameter>
4031 field is also specified.
4037 <term><parameter>width
</parameter> (optional)
</term>
4040 Specifies the
<emphasis>minimum
</emphasis> number of characters to use to
4041 display the format specifier's output. The output is padded on the
4042 left or right (depending on the
<literal>-
</literal> flag) with spaces as
4043 needed to fill the width. A too-small width does not cause
4044 truncation of the output, but is simply ignored. The width may be
4045 specified using any of the following: a positive integer; an
4046 asterisk (
<literal>*
</literal>) to use the next function argument as the
4047 width; or a string of the form
<literal>*
<parameter>n
</parameter>$
</literal> to
4048 use the
<parameter>n
</parameter>th function argument as the width.
4052 If the width comes from a function argument, that argument is
4053 consumed before the argument that is used for the format specifier's
4054 value. If the width argument is negative, the result is left
4055 aligned (as if the
<literal>-
</literal> flag had been specified) within a
4056 field of length
<function>abs
</function>(
<parameter>width
</parameter>).
4062 <term><parameter>type
</parameter> (required)
</term>
4065 The type of format conversion to use to produce the format
4066 specifier's output. The following types are supported:
4070 <literal>s
</literal> formats the argument value as a simple
4071 string. A null value is treated as an empty string.
4076 <literal>I
</literal> treats the argument value as an SQL
4077 identifier, double-quoting it if necessary.
4078 It is an error for the value to be null (equivalent to
4079 <function>quote_ident
</function>).
4084 <literal>L
</literal> quotes the argument value as an SQL literal.
4085 A null value is displayed as the string
<literal>NULL
</literal>, without
4086 quotes (equivalent to
<function>quote_nullable
</function>).
4097 In addition to the format specifiers described above, the special sequence
4098 <literal>%%
</literal> may be used to output a literal
<literal>%
</literal> character.
4102 Here are some examples of the basic format conversions:
4105 SELECT format('Hello %s', 'World');
4106 <lineannotation>Result:
</lineannotation><computeroutput>Hello World
</computeroutput>
4108 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
4109 <lineannotation>Result:
</lineannotation><computeroutput>Testing one, two, three, %
</computeroutput>
4111 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
4112 <lineannotation>Result:
</lineannotation><computeroutput>INSERT INTO
"Foo bar" VALUES('O''Reilly')
</computeroutput>
4114 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
4115 <lineannotation>Result:
</lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')
</computeroutput>
4120 Here are examples using
<parameter>width
</parameter> fields
4121 and the
<literal>-
</literal> flag:
4124 SELECT format('|%
10s|', 'foo');
4125 <lineannotation>Result:
</lineannotation><computeroutput>| foo|
</computeroutput>
4127 SELECT format('|%-
10s|', 'foo');
4128 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4130 SELECT format('|%*s|',
10, 'foo');
4131 <lineannotation>Result:
</lineannotation><computeroutput>| foo|
</computeroutput>
4133 SELECT format('|%*s|', -
10, 'foo');
4134 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4136 SELECT format('|%-*s|',
10, 'foo');
4137 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4139 SELECT format('|%-*s|', -
10, 'foo');
4140 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4145 These examples show use of
<parameter>position
</parameter> fields:
4148 SELECT format('Testing %
3$s, %
2$s, %
1$s', 'one', 'two', 'three');
4149 <lineannotation>Result:
</lineannotation><computeroutput>Testing three, two, one
</computeroutput>
4151 SELECT format('|%*
2$s|', 'foo',
10, 'bar');
4152 <lineannotation>Result:
</lineannotation><computeroutput>| bar|
</computeroutput>
4154 SELECT format('|%
1$*
2$s|', 'foo',
10, 'bar');
4155 <lineannotation>Result:
</lineannotation><computeroutput>| foo|
</computeroutput>
4160 Unlike the standard C function
<function>sprintf
</function>,
4161 <productname>PostgreSQL
</productname>'s
<function>format
</function> function allows format
4162 specifiers with and without
<parameter>position
</parameter> fields to be mixed
4163 in the same format string. A format specifier without a
4164 <parameter>position
</parameter> field always uses the next argument after the
4165 last argument consumed.
4166 In addition, the
<function>format
</function> function does not require all
4167 function arguments to be used in the format string.
4171 SELECT format('Testing %
3$s, %
2$s, %s', 'one', 'two', 'three');
4172 <lineannotation>Result:
</lineannotation><computeroutput>Testing three, two, three
</computeroutput>
4177 The
<literal>%I
</literal> and
<literal>%L
</literal> format specifiers are particularly
4178 useful for safely constructing dynamic SQL statements. See
4179 <xref linkend=
"plpgsql-quote-literal-example"/>.
4186 <sect1 id=
"functions-binarystring">
4187 <title>Binary String Functions and Operators
</title>
4189 <indexterm zone=
"functions-binarystring">
4190 <primary>binary data
</primary>
4191 <secondary>functions
</secondary>
4195 This section describes functions and operators for examining and
4196 manipulating binary strings, that is values of type
<type>bytea
</type>.
4197 Many of these are equivalent, in purpose and syntax, to the
4198 text-string functions described in the previous section.
4202 <acronym>SQL
</acronym> defines some string functions that use
4203 key words, rather than commas, to separate
4204 arguments. Details are in
4205 <xref linkend=
"functions-binarystring-sql"/>.
4206 <productname>PostgreSQL
</productname> also provides versions of these functions
4207 that use the regular function invocation syntax
4208 (see
<xref linkend=
"functions-binarystring-other"/>).
4211 <table id=
"functions-binarystring-sql">
4212 <title><acronym>SQL
</acronym> Binary String Functions and Operators
</title>
4216 <entry role=
"func_table_entry"><para role=
"func_signature">
4230 <entry role=
"func_table_entry"><para role=
"func_signature">
4232 <primary>binary string
</primary>
4233 <secondary>concatenation
</secondary>
4235 <type>bytea
</type> <literal>||
</literal> <type>bytea
</type>
4236 <returnvalue>bytea
</returnvalue>
4239 Concatenates the two binary strings.
4242 <literal>'\x123456'::bytea || '\x789a00bcde'::bytea
</literal>
4243 <returnvalue>\x123456789a00bcde
</returnvalue>
4248 <entry role=
"func_table_entry"><para role=
"func_signature">
4250 <primary>bit_length
</primary>
4252 <function>bit_length
</function> (
<type>bytea
</type> )
4253 <returnvalue>integer
</returnvalue>
4256 Returns number of bits in the binary string (
8
4257 times the
<function>octet_length
</function>).
4260 <literal>bit_length('\x123456'::bytea)
</literal>
4261 <returnvalue>24</returnvalue>
4266 <entry role=
"func_table_entry"><para role=
"func_signature">
4268 <primary>btrim
</primary>
4270 <function>btrim
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4271 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4272 <returnvalue>bytea
</returnvalue>
4275 Removes the longest string containing only bytes appearing in
4276 <parameter>bytesremoved
</parameter> from the start and end of
4277 <parameter>bytes
</parameter>.
4280 <literal>btrim('\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4281 <returnvalue>\x345678
</returnvalue>
4286 <entry role=
"func_table_entry"><para role=
"func_signature">
4288 <primary>ltrim
</primary>
4290 <function>ltrim
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4291 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4292 <returnvalue>bytea
</returnvalue>
4295 Removes the longest string containing only bytes appearing in
4296 <parameter>bytesremoved
</parameter> from the start of
4297 <parameter>bytes
</parameter>.
4300 <literal>ltrim('\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4301 <returnvalue>\x34567890
</returnvalue>
4306 <entry role=
"func_table_entry"><para role=
"func_signature">
4308 <primary>octet_length
</primary>
4310 <function>octet_length
</function> (
<type>bytea
</type> )
4311 <returnvalue>integer
</returnvalue>
4314 Returns number of bytes in the binary string.
4317 <literal>octet_length('\x123456'::bytea)
</literal>
4318 <returnvalue>3</returnvalue>
4323 <entry role=
"func_table_entry"><para role=
"func_signature">
4325 <primary>overlay
</primary>
4327 <function>overlay
</function> (
<parameter>bytes
</parameter> <type>bytea
</type> <literal>PLACING
</literal> <parameter>newsubstring
</parameter> <type>bytea
</type> <literal>FROM
</literal> <parameter>start
</parameter> <type>integer
</type> <optional> <literal>FOR
</literal> <parameter>count
</parameter> <type>integer
</type> </optional> )
4328 <returnvalue>bytea
</returnvalue>
4331 Replaces the substring of
<parameter>bytes
</parameter> that starts at
4332 the
<parameter>start
</parameter>'th byte and extends
4333 for
<parameter>count
</parameter> bytes
4334 with
<parameter>newsubstring
</parameter>.
4335 If
<parameter>count
</parameter> is omitted, it defaults to the length
4336 of
<parameter>newsubstring
</parameter>.
4339 <literal>overlay('\x1234567890'::bytea placing '\
002\
003'::bytea from
2 for
3)
</literal>
4340 <returnvalue>\x12020390
</returnvalue>
4345 <entry role=
"func_table_entry"><para role=
"func_signature">
4347 <primary>position
</primary>
4349 <function>position
</function> (
<parameter>substring
</parameter> <type>bytea
</type> <literal>IN
</literal> <parameter>bytes
</parameter> <type>bytea
</type> )
4350 <returnvalue>integer
</returnvalue>
4353 Returns first starting index of the specified
4354 <parameter>substring
</parameter> within
4355 <parameter>bytes
</parameter>, or zero if it's not present.
4358 <literal>position('\x5678'::bytea in '\x1234567890'::bytea)
</literal>
4359 <returnvalue>3</returnvalue>
4364 <entry role=
"func_table_entry"><para role=
"func_signature">
4366 <primary>rtrim
</primary>
4368 <function>rtrim
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4369 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4370 <returnvalue>bytea
</returnvalue>
4373 Removes the longest string containing only bytes appearing in
4374 <parameter>bytesremoved
</parameter> from the end of
4375 <parameter>bytes
</parameter>.
4378 <literal>rtrim('\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4379 <returnvalue>\x12345678
</returnvalue>
4384 <entry role=
"func_table_entry"><para role=
"func_signature">
4386 <primary>substring
</primary>
4388 <function>substring
</function> (
<parameter>bytes
</parameter> <type>bytea
</type> <optional> <literal>FROM
</literal> <parameter>start
</parameter> <type>integer
</type> </optional> <optional> <literal>FOR
</literal> <parameter>count
</parameter> <type>integer
</type> </optional> )
4389 <returnvalue>bytea
</returnvalue>
4392 Extracts the substring of
<parameter>bytes
</parameter> starting at
4393 the
<parameter>start
</parameter>'th byte if that is specified,
4394 and stopping after
<parameter>count
</parameter> bytes if that is
4395 specified. Provide at least one of
<parameter>start
</parameter>
4396 and
<parameter>count
</parameter>.
4399 <literal>substring('\x1234567890'::bytea from
3 for
2)
</literal>
4400 <returnvalue>\x5678
</returnvalue>
4405 <entry role=
"func_table_entry"><para role=
"func_signature">
4407 <primary>trim
</primary>
4409 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional>
4410 <parameter>bytesremoved
</parameter> <type>bytea
</type> <literal>FROM
</literal>
4411 <parameter>bytes
</parameter> <type>bytea
</type> )
4412 <returnvalue>bytea
</returnvalue>
4415 Removes the longest string containing only bytes appearing in
4416 <parameter>bytesremoved
</parameter> from the start,
4417 end, or both ends (
<literal>BOTH
</literal> is the default)
4418 of
<parameter>bytes
</parameter>.
4421 <literal>trim('\x9012'::bytea from '\x1234567890'::bytea)
</literal>
4422 <returnvalue>\x345678
</returnvalue>
4427 <entry role=
"func_table_entry"><para role=
"func_signature">
4428 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional> <optional> <literal>FROM
</literal> </optional>
4429 <parameter>bytes
</parameter> <type>bytea
</type>,
4430 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4431 <returnvalue>bytea
</returnvalue>
4434 This is a non-standard syntax for
<function>trim()
</function>.
4437 <literal>trim(both from '\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4438 <returnvalue>\x345678
</returnvalue>
4446 Additional binary string manipulation functions are available and
4447 are listed in
<xref linkend=
"functions-binarystring-other"/>. Some
4448 of them are used internally to implement the
4449 <acronym>SQL
</acronym>-standard string functions listed in
<xref
4450 linkend=
"functions-binarystring-sql"/>.
4453 <table id=
"functions-binarystring-other">
4454 <title>Other Binary String Functions
</title>
4458 <entry role=
"func_table_entry"><para role=
"func_signature">
4472 <entry role=
"func_table_entry"><para role=
"func_signature">
4474 <primary>bit_count
</primary>
4477 <primary>popcount
</primary>
4478 <see>bit_count
</see>
4480 <function>bit_count
</function> (
<parameter>bytes
</parameter> <type>bytea
</type> )
4481 <returnvalue>bigint
</returnvalue>
4484 Returns the number of bits set in the binary string (also known as
4485 <quote>popcount
</quote>).
4488 <literal>bit_count('\x1234567890'::bytea)
</literal>
4489 <returnvalue>15</returnvalue>
4494 <entry role=
"func_table_entry"><para role=
"func_signature">
4496 <primary>crc32
</primary>
4498 <function>crc32
</function> (
<type>bytea
</type> )
4499 <returnvalue>bigint
</returnvalue>
4502 Computes the CRC-
32 value of the binary string.
4505 <literal>crc32('abc'::bytea)
</literal>
4506 <returnvalue>891568578</returnvalue>
4511 <entry role=
"func_table_entry"><para role=
"func_signature">
4513 <primary>crc32c
</primary>
4515 <function>crc32c
</function> (
<type>bytea
</type> )
4516 <returnvalue>bigint
</returnvalue>
4519 Computes the CRC-
32C value of the binary string.
4522 <literal>crc32c('abc'::bytea)
</literal>
4523 <returnvalue>910901175</returnvalue>
4528 <entry role=
"func_table_entry"><para role=
"func_signature">
4530 <primary>get_bit
</primary>
4532 <function>get_bit
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4533 <parameter>n
</parameter> <type>bigint
</type> )
4534 <returnvalue>integer
</returnvalue>
4537 Extracts
<link linkend=
"functions-zerobased-note">n'th
</link> bit
4541 <literal>get_bit('\x1234567890'::bytea,
30)
</literal>
4542 <returnvalue>1</returnvalue>
4547 <entry role=
"func_table_entry"><para role=
"func_signature">
4549 <primary>get_byte
</primary>
4551 <function>get_byte
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4552 <parameter>n
</parameter> <type>integer
</type> )
4553 <returnvalue>integer
</returnvalue>
4556 Extracts
<link linkend=
"functions-zerobased-note">n'th
</link> byte
4560 <literal>get_byte('\x1234567890'::bytea,
4)
</literal>
4561 <returnvalue>144</returnvalue>
4566 <entry role=
"func_table_entry"><para role=
"func_signature">
4568 <primary>length
</primary>
4571 <primary>binary string
</primary>
4572 <secondary>length
</secondary>
4575 <primary>length
</primary>
4576 <secondary sortas=
"binary string">of a binary string
</secondary>
4577 <see>binary strings, length
</see>
4579 <function>length
</function> (
<type>bytea
</type> )
4580 <returnvalue>integer
</returnvalue>
4583 Returns the number of bytes in the binary string.
4586 <literal>length('\x1234567890'::bytea)
</literal>
4587 <returnvalue>5</returnvalue>
4592 <entry role=
"func_table_entry"><para role=
"func_signature">
4593 <function>length
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4594 <parameter>encoding
</parameter> <type>name
</type> )
4595 <returnvalue>integer
</returnvalue>
4598 Returns the number of characters in the binary string, assuming
4599 that it is text in the given
<parameter>encoding
</parameter>.
4602 <literal>length('jose'::bytea, 'UTF8')
</literal>
4603 <returnvalue>4</returnvalue>
4608 <entry role=
"func_table_entry"><para role=
"func_signature">
4610 <primary>md5
</primary>
4612 <function>md5
</function> (
<type>bytea
</type> )
4613 <returnvalue>text
</returnvalue>
4616 Computes the MD5
<link linkend=
"functions-hash-note">hash
</link> of
4617 the binary string, with the result written in hexadecimal.
4620 <literal>md5('Th\
000omas'::bytea)
</literal>
4621 <returnvalue>8ab2d3c9689aaf18
&zwsp;b4958c334c82d8b1
</returnvalue>
4626 <entry role=
"func_table_entry"><para role=
"func_signature">
4628 <primary>set_bit
</primary>
4630 <function>set_bit
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4631 <parameter>n
</parameter> <type>bigint
</type>,
4632 <parameter>newvalue
</parameter> <type>integer
</type> )
4633 <returnvalue>bytea
</returnvalue>
4636 Sets
<link linkend=
"functions-zerobased-note">n'th
</link> bit in
4637 binary string to
<parameter>newvalue
</parameter>.
4640 <literal>set_bit('\x1234567890'::bytea,
30,
0)
</literal>
4641 <returnvalue>\x1234563890
</returnvalue>
4646 <entry role=
"func_table_entry"><para role=
"func_signature">
4648 <primary>set_byte
</primary>
4650 <function>set_byte
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4651 <parameter>n
</parameter> <type>integer
</type>,
4652 <parameter>newvalue
</parameter> <type>integer
</type> )
4653 <returnvalue>bytea
</returnvalue>
4656 Sets
<link linkend=
"functions-zerobased-note">n'th
</link> byte in
4657 binary string to
<parameter>newvalue
</parameter>.
4660 <literal>set_byte('\x1234567890'::bytea,
4,
64)
</literal>
4661 <returnvalue>\x1234567840
</returnvalue>
4666 <entry role=
"func_table_entry"><para role=
"func_signature">
4668 <primary>sha224
</primary>
4670 <function>sha224
</function> (
<type>bytea
</type> )
4671 <returnvalue>bytea
</returnvalue>
4674 Computes the SHA-
224 <link linkend=
"functions-hash-note">hash
</link>
4675 of the binary string.
4678 <literal>sha224('abc'::bytea)
</literal>
4679 <returnvalue>\x23097d223405d8228642a477bda2
&zwsp;55b32aadbce4bda0b3f7e36c9da7
</returnvalue>
4684 <entry role=
"func_table_entry"><para role=
"func_signature">
4686 <primary>sha256
</primary>
4688 <function>sha256
</function> (
<type>bytea
</type> )
4689 <returnvalue>bytea
</returnvalue>
4692 Computes the SHA-
256 <link linkend=
"functions-hash-note">hash
</link>
4693 of the binary string.
4696 <literal>sha256('abc'::bytea)
</literal>
4697 <returnvalue>\xba7816bf8f01cfea414140de5dae2223
&zwsp;b00361a396177a9cb410ff61f20015ad
</returnvalue>
4702 <entry role=
"func_table_entry"><para role=
"func_signature">
4704 <primary>sha384
</primary>
4706 <function>sha384
</function> (
<type>bytea
</type> )
4707 <returnvalue>bytea
</returnvalue>
4710 Computes the SHA-
384 <link linkend=
"functions-hash-note">hash
</link>
4711 of the binary string.
4714 <literal>sha384('abc'::bytea)
</literal>
4715 <returnvalue>\xcb00753f45a35e8bb5a03d699ac65007
&zwsp;272c32ab0eded1631a8b605a43ff5bed
&zwsp;8086072ba1e7cc2358baeca134c825a7
</returnvalue>
4720 <entry role=
"func_table_entry"><para role=
"func_signature">
4722 <primary>sha512
</primary>
4724 <function>sha512
</function> (
<type>bytea
</type> )
4725 <returnvalue>bytea
</returnvalue>
4728 Computes the SHA-
512 <link linkend=
"functions-hash-note">hash
</link>
4729 of the binary string.
4732 <literal>sha512('abc'::bytea)
</literal>
4733 <returnvalue>\xddaf35a193617abacc417349ae204131
&zwsp;12e6fa4e89a97ea20a9eeee64b55d39a
&zwsp;2192992a274fc1a836ba3c23a3feebbd
&zwsp;454d4423643ce80e2a9ac94fa54ca49f
</returnvalue>
4738 <entry role=
"func_table_entry"><para role=
"func_signature">
4740 <primary>substr
</primary>
4742 <function>substr
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
<parameter>start
</parameter> <type>integer
</type> <optional>,
<parameter>count
</parameter> <type>integer
</type> </optional> )
4743 <returnvalue>bytea
</returnvalue>
4746 Extracts the substring of
<parameter>bytes
</parameter> starting at
4747 the
<parameter>start
</parameter>'th byte,
4748 and extending for
<parameter>count
</parameter> bytes if that is
4750 as
<literal>substring(
<parameter>bytes
</parameter>
4751 from
<parameter>start
</parameter>
4752 for
<parameter>count
</parameter>)
</literal>.)
4755 <literal>substr('\x1234567890'::bytea,
3,
2)
</literal>
4756 <returnvalue>\x5678
</returnvalue>
4763 <para id=
"functions-zerobased-note">
4764 Functions
<function>get_byte
</function> and
<function>set_byte
</function>
4765 number the first byte of a binary string as byte
0.
4766 Functions
<function>get_bit
</function> and
<function>set_bit
</function>
4767 number bits from the right within each byte; for example bit
0 is the least
4768 significant bit of the first byte, and bit
15 is the most significant bit
4772 <para id=
"functions-hash-note">
4773 For historical reasons, the function
<function>md5
</function>
4774 returns a hex-encoded value of type
<type>text
</type> whereas the SHA-
2
4775 functions return type
<type>bytea
</type>. Use the functions
4776 <link linkend=
"function-encode"><function>encode
</function></link>
4777 and
<link linkend=
"function-decode"><function>decode
</function></link> to
4778 convert between the two. For example write
<literal>encode(sha256('abc'),
4779 'hex')
</literal> to get a hex-encoded text representation,
4780 or
<literal>decode(md5('abc'), 'hex')
</literal> to get
4781 a
<type>bytea
</type> value.
4786 <primary>character string
</primary>
4787 <secondary>converting to binary string
</secondary>
4790 <primary>binary string
</primary>
4791 <secondary>converting to character string
</secondary>
4793 Functions for converting strings between different character sets
4794 (encodings), and for representing arbitrary binary data in textual
4796 <xref linkend=
"functions-binarystring-conversions"/>. For these
4797 functions, an argument or result of type
<type>text
</type> is expressed
4798 in the database's default encoding, while arguments or results of
4799 type
<type>bytea
</type> are in an encoding named by another argument.
4802 <table id=
"functions-binarystring-conversions">
4803 <title>Text/Binary String Conversion Functions
</title>
4807 <entry role=
"func_table_entry"><para role=
"func_signature">
4821 <entry role=
"func_table_entry"><para role=
"func_signature">
4823 <primary>convert
</primary>
4825 <function>convert
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4826 <parameter>src_encoding
</parameter> <type>name
</type>,
4827 <parameter>dest_encoding
</parameter> <type>name
</type> )
4828 <returnvalue>bytea
</returnvalue>
4831 Converts a binary string representing text in
4832 encoding
<parameter>src_encoding
</parameter>
4833 to a binary string in encoding
<parameter>dest_encoding
</parameter>
4834 (see
<xref linkend=
"multibyte-conversions-supported"/> for
4835 available conversions).
4838 <literal>convert('text_in_utf8', 'UTF8', 'LATIN1')
</literal>
4839 <returnvalue>\x746578745f696e5f75746638
</returnvalue>
4844 <entry role=
"func_table_entry"><para role=
"func_signature">
4846 <primary>convert_from
</primary>
4848 <function>convert_from
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4849 <parameter>src_encoding
</parameter> <type>name
</type> )
4850 <returnvalue>text
</returnvalue>
4853 Converts a binary string representing text in
4854 encoding
<parameter>src_encoding
</parameter>
4855 to
<type>text
</type> in the database encoding
4856 (see
<xref linkend=
"multibyte-conversions-supported"/> for
4857 available conversions).
4860 <literal>convert_from('text_in_utf8', 'UTF8')
</literal>
4861 <returnvalue>text_in_utf8
</returnvalue>
4866 <entry role=
"func_table_entry"><para role=
"func_signature">
4868 <primary>convert_to
</primary>
4870 <function>convert_to
</function> (
<parameter>string
</parameter> <type>text
</type>,
4871 <parameter>dest_encoding
</parameter> <type>name
</type> )
4872 <returnvalue>bytea
</returnvalue>
4875 Converts a
<type>text
</type> string (in the database encoding) to a
4876 binary string encoded in encoding
<parameter>dest_encoding
</parameter>
4877 (see
<xref linkend=
"multibyte-conversions-supported"/> for
4878 available conversions).
4881 <literal>convert_to('some_text', 'UTF8')
</literal>
4882 <returnvalue>\x736f6d655f74657874
</returnvalue>
4887 <entry role=
"func_table_entry"><para role=
"func_signature">
4888 <indexterm id=
"function-encode">
4889 <primary>encode
</primary>
4891 <function>encode
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4892 <parameter>format
</parameter> <type>text
</type> )
4893 <returnvalue>text
</returnvalue>
4896 Encodes binary data into a textual representation; supported
4897 <parameter>format
</parameter> values are:
4898 <link linkend=
"encode-format-base64"><literal>base64
</literal></link>,
4899 <link linkend=
"encode-format-escape"><literal>escape
</literal></link>,
4900 <link linkend=
"encode-format-hex"><literal>hex
</literal></link>.
4903 <literal>encode('
123\
000\
001', 'base64')
</literal>
4904 <returnvalue>MTIzAAE=
</returnvalue>
4909 <entry role=
"func_table_entry"><para role=
"func_signature">
4910 <indexterm id=
"function-decode">
4911 <primary>decode
</primary>
4913 <function>decode
</function> (
<parameter>string
</parameter> <type>text
</type>,
4914 <parameter>format
</parameter> <type>text
</type> )
4915 <returnvalue>bytea
</returnvalue>
4918 Decodes binary data from a textual representation; supported
4919 <parameter>format
</parameter> values are the same as
4920 for
<function>encode
</function>.
4923 <literal>decode('MTIzAAE=', 'base64')
</literal>
4924 <returnvalue>\x3132330001
</returnvalue>
4932 The
<function>encode
</function> and
<function>decode
</function>
4933 functions support the following textual formats:
4936 <varlistentry id=
"encode-format-base64">
4939 <primary>base64 format
</primary>
4943 The
<literal>base64
</literal> format is that
4944 of
<ulink url=
"https://datatracker.ietf.org/doc/html/rfc2045#section-6.8">RFC
4945 2045 Section
6.8</ulink>. As per the
<acronym>RFC
</acronym>, encoded lines are
4946 broken at
76 characters. However instead of the MIME CRLF
4947 end-of-line marker, only a newline is used for end-of-line.
4948 The
<function>decode
</function> function ignores carriage-return,
4949 newline, space, and tab characters. Otherwise, an error is
4950 raised when
<function>decode
</function> is supplied invalid
4951 base64 data
— including when trailing padding is incorrect.
4956 <varlistentry id=
"encode-format-escape">
4959 <primary>escape format
</primary>
4963 The
<literal>escape
</literal> format converts zero bytes and
4964 bytes with the high bit set into octal escape sequences
4965 (
<literal>\
</literal><replaceable>nnn
</replaceable>), and it doubles
4966 backslashes. Other byte values are represented literally.
4967 The
<function>decode
</function> function will raise an error if a
4968 backslash is not followed by either a second backslash or three
4969 octal digits; it accepts other byte values unchanged.
4974 <varlistentry id=
"encode-format-hex">
4977 <primary>hex format
</primary>
4981 The
<literal>hex
</literal> format represents each
4 bits of
4982 data as one hexadecimal digit,
<literal>0</literal>
4983 through
<literal>f
</literal>, writing the higher-order digit of
4984 each byte first. The
<function>encode
</function> function outputs
4985 the
<literal>a
</literal>-
<literal>f
</literal> hex digits in lower
4986 case. Because the smallest unit of data is
8 bits, there are
4987 always an even number of characters returned
4988 by
<function>encode
</function>.
4989 The
<function>decode
</function> function
4990 accepts the
<literal>a
</literal>-
<literal>f
</literal> characters in
4991 either upper or lower case. An error is raised
4992 when
<function>decode
</function> is given invalid hex data
4993 — including when given an odd number of characters.
5001 See also the aggregate function
<function>string_agg
</function> in
5002 <xref linkend=
"functions-aggregate"/> and the large object functions
5003 in
<xref linkend=
"lo-funcs"/>.
5008 <sect1 id=
"functions-bitstring">
5009 <title>Bit String Functions and Operators
</title>
5011 <indexterm zone=
"functions-bitstring">
5012 <primary>bit strings
</primary>
5013 <secondary>functions
</secondary>
5017 This section describes functions and operators for examining and
5018 manipulating bit strings, that is values of the types
5019 <type>bit
</type> and
<type>bit varying
</type>. (While only
5020 type
<type>bit
</type> is mentioned in these tables, values of
5021 type
<type>bit varying
</type> can be used interchangeably.)
5022 Bit strings support the usual comparison operators shown in
5023 <xref linkend=
"functions-comparison-op-table"/>, as well as the
5024 operators shown in
<xref linkend=
"functions-bit-string-op-table"/>.
5027 <table id=
"functions-bit-string-op-table">
5028 <title>Bit String Operators
</title>
5032 <entry role=
"func_table_entry"><para role=
"func_signature">
5046 <entry role=
"func_table_entry"><para role=
"func_signature">
5047 <type>bit
</type> <literal>||
</literal> <type>bit
</type>
5048 <returnvalue>bit
</returnvalue>
5054 <literal>B'
10001' || B'
011'
</literal>
5055 <returnvalue>10001011</returnvalue>
5060 <entry role=
"func_table_entry"><para role=
"func_signature">
5061 <type>bit
</type> <literal>&</literal> <type>bit
</type>
5062 <returnvalue>bit
</returnvalue>
5065 Bitwise AND (inputs must be of equal length)
5068 <literal>B'
10001'
& B'
01101'
</literal>
5069 <returnvalue>00001</returnvalue>
5074 <entry role=
"func_table_entry"><para role=
"func_signature">
5075 <type>bit
</type> <literal>|
</literal> <type>bit
</type>
5076 <returnvalue>bit
</returnvalue>
5079 Bitwise OR (inputs must be of equal length)
5082 <literal>B'
10001' | B'
01101'
</literal>
5083 <returnvalue>11101</returnvalue>
5088 <entry role=
"func_table_entry"><para role=
"func_signature">
5089 <type>bit
</type> <literal>#
</literal> <type>bit
</type>
5090 <returnvalue>bit
</returnvalue>
5093 Bitwise exclusive OR (inputs must be of equal length)
5096 <literal>B'
10001' # B'
01101'
</literal>
5097 <returnvalue>11100</returnvalue>
5102 <entry role=
"func_table_entry"><para role=
"func_signature">
5103 <literal>~
</literal> <type>bit
</type>
5104 <returnvalue>bit
</returnvalue>
5110 <literal>~ B'
10001'
</literal>
5111 <returnvalue>01110</returnvalue>
5116 <entry role=
"func_table_entry"><para role=
"func_signature">
5117 <type>bit
</type> <literal><<</literal> <type>integer
</type>
5118 <returnvalue>bit
</returnvalue>
5122 (string length is preserved)
5125 <literal>B'
10001'
<< 3</literal>
5126 <returnvalue>01000</returnvalue>
5131 <entry role=
"func_table_entry"><para role=
"func_signature">
5132 <type>bit
</type> <literal>>></literal> <type>integer
</type>
5133 <returnvalue>bit
</returnvalue>
5137 (string length is preserved)
5140 <literal>B'
10001'
>> 2</literal>
5141 <returnvalue>00100</returnvalue>
5149 Some of the functions available for binary strings are also available
5150 for bit strings, as shown in
<xref linkend=
"functions-bit-string-table"/>.
5153 <table id=
"functions-bit-string-table">
5154 <title>Bit String Functions
</title>
5158 <entry role=
"func_table_entry"><para role=
"func_signature">
5172 <entry role=
"func_table_entry"><para role=
"func_signature">
5174 <primary>bit_count
</primary>
5176 <function>bit_count
</function> (
<type>bit
</type> )
5177 <returnvalue>bigint
</returnvalue>
5180 Returns the number of bits set in the bit string (also known as
5181 <quote>popcount
</quote>).
5184 <literal>bit_count(B'
10111')
</literal>
5185 <returnvalue>4</returnvalue>
5190 <entry role=
"func_table_entry"><para role=
"func_signature">
5192 <primary>bit_length
</primary>
5194 <function>bit_length
</function> (
<type>bit
</type> )
5195 <returnvalue>integer
</returnvalue>
5198 Returns number of bits in the bit string.
5201 <literal>bit_length(B'
10111')
</literal>
5202 <returnvalue>5</returnvalue>
5207 <entry role=
"func_table_entry"><para role=
"func_signature">
5209 <primary>length
</primary>
5212 <primary>bit string
</primary>
5213 <secondary>length
</secondary>
5215 <function>length
</function> (
<type>bit
</type> )
5216 <returnvalue>integer
</returnvalue>
5219 Returns number of bits in the bit string.
5222 <literal>length(B'
10111')
</literal>
5223 <returnvalue>5</returnvalue>
5228 <entry role=
"func_table_entry"><para role=
"func_signature">
5230 <primary>octet_length
</primary>
5232 <function>octet_length
</function> (
<type>bit
</type> )
5233 <returnvalue>integer
</returnvalue>
5236 Returns number of bytes in the bit string.
5239 <literal>octet_length(B'
1011111011')
</literal>
5240 <returnvalue>2</returnvalue>
5245 <entry role=
"func_table_entry"><para role=
"func_signature">
5247 <primary>overlay
</primary>
5249 <function>overlay
</function> (
<parameter>bits
</parameter> <type>bit
</type> <literal>PLACING
</literal> <parameter>newsubstring
</parameter> <type>bit
</type> <literal>FROM
</literal> <parameter>start
</parameter> <type>integer
</type> <optional> <literal>FOR
</literal> <parameter>count
</parameter> <type>integer
</type> </optional> )
5250 <returnvalue>bit
</returnvalue>
5253 Replaces the substring of
<parameter>bits
</parameter> that starts at
5254 the
<parameter>start
</parameter>'th bit and extends
5255 for
<parameter>count
</parameter> bits
5256 with
<parameter>newsubstring
</parameter>.
5257 If
<parameter>count
</parameter> is omitted, it defaults to the length
5258 of
<parameter>newsubstring
</parameter>.
5261 <literal>overlay(B'
01010101010101010' placing B'
11111' from
2 for
3)
</literal>
5262 <returnvalue>0111110101010101010</returnvalue>
5267 <entry role=
"func_table_entry"><para role=
"func_signature">
5269 <primary>position
</primary>
5271 <function>position
</function> (
<parameter>substring
</parameter> <type>bit
</type> <literal>IN
</literal> <parameter>bits
</parameter> <type>bit
</type> )
5272 <returnvalue>integer
</returnvalue>
5275 Returns first starting index of the specified
<parameter>substring
</parameter>
5276 within
<parameter>bits
</parameter>, or zero if it's not present.
5279 <literal>position(B'
010' in B'
000001101011')
</literal>
5280 <returnvalue>8</returnvalue>
5285 <entry role=
"func_table_entry"><para role=
"func_signature">
5287 <primary>substring
</primary>
5289 <function>substring
</function> (
<parameter>bits
</parameter> <type>bit
</type> <optional> <literal>FROM
</literal> <parameter>start
</parameter> <type>integer
</type> </optional> <optional> <literal>FOR
</literal> <parameter>count
</parameter> <type>integer
</type> </optional> )
5290 <returnvalue>bit
</returnvalue>
5293 Extracts the substring of
<parameter>bits
</parameter> starting at
5294 the
<parameter>start
</parameter>'th bit if that is specified,
5295 and stopping after
<parameter>count
</parameter> bits if that is
5296 specified. Provide at least one of
<parameter>start
</parameter>
5297 and
<parameter>count
</parameter>.
5300 <literal>substring(B'
110010111111' from
3 for
2)
</literal>
5301 <returnvalue>00</returnvalue>
5306 <entry role=
"func_table_entry"><para role=
"func_signature">
5308 <primary>get_bit
</primary>
5310 <function>get_bit
</function> (
<parameter>bits
</parameter> <type>bit
</type>,
5311 <parameter>n
</parameter> <type>integer
</type> )
5312 <returnvalue>integer
</returnvalue>
5315 Extracts
<parameter>n
</parameter>'th bit
5316 from bit string; the first (leftmost) bit is bit
0.
5319 <literal>get_bit(B'
101010101010101010',
6)
</literal>
5320 <returnvalue>1</returnvalue>
5325 <entry role=
"func_table_entry"><para role=
"func_signature">
5327 <primary>set_bit
</primary>
5329 <function>set_bit
</function> (
<parameter>bits
</parameter> <type>bit
</type>,
5330 <parameter>n
</parameter> <type>integer
</type>,
5331 <parameter>newvalue
</parameter> <type>integer
</type> )
5332 <returnvalue>bit
</returnvalue>
5335 Sets
<parameter>n
</parameter>'th bit in
5336 bit string to
<parameter>newvalue
</parameter>;
5337 the first (leftmost) bit is bit
0.
5340 <literal>set_bit(B'
101010101010101010',
6,
0)
</literal>
5341 <returnvalue>101010001010101010</returnvalue>
5349 In addition, it is possible to cast integral values to and from type
5351 Casting an integer to
<type>bit(n)
</type> copies the rightmost
5352 <literal>n
</literal> bits. Casting an integer to a bit string width wider
5353 than the integer itself will sign-extend on the left.
5356 44::bit(
10)
<lineannotation>0000101100</lineannotation>
5357 44::bit(
3)
<lineannotation>100</lineannotation>
5358 cast(-
44 as bit(
12))
<lineannotation>111111010100</lineannotation>
5359 '
1110'::bit(
4)::integer
<lineannotation>14</lineannotation>
5361 Note that casting to just
<quote>bit
</quote> means casting to
5362 <literal>bit(
1)
</literal>, and so will deliver only the least significant
5368 <sect1 id=
"functions-matching">
5369 <title>Pattern Matching
</title>
5371 <indexterm zone=
"functions-matching">
5372 <primary>pattern matching
</primary>
5376 There are three separate approaches to pattern matching provided
5377 by
<productname>PostgreSQL
</productname>: the traditional
5378 <acronym>SQL
</acronym> <function>LIKE
</function> operator, the
5379 more recent
<function>SIMILAR TO
</function> operator (added in
5380 SQL:
1999), and
<acronym>POSIX
</acronym>-style regular
5381 expressions. Aside from the basic
<quote>does this string match
5382 this pattern?
</quote> operators, functions are available to extract
5383 or replace matching substrings and to split a string at matching
5389 If you have pattern matching needs that go beyond this,
5390 consider writing a user-defined function in Perl or Tcl.
5396 While most regular-expression searches can be executed very quickly,
5397 regular expressions can be contrived that take arbitrary amounts of
5398 time and memory to process. Be wary of accepting regular-expression
5399 search patterns from hostile sources. If you must do so, it is
5400 advisable to impose a statement timeout.
5404 Searches using
<function>SIMILAR TO
</function> patterns have the same
5405 security hazards, since
<function>SIMILAR TO
</function> provides many
5406 of the same capabilities as
<acronym>POSIX
</acronym>-style regular
5411 <function>LIKE
</function> searches, being much simpler than the other
5412 two options, are safer to use with possibly-hostile pattern sources.
5417 The pattern matching operators of all three kinds do not support
5418 nondeterministic collations. If required, apply a different collation to
5419 the expression to work around this limitation.
5422 <sect2 id=
"functions-like">
5423 <title><function>LIKE
</function></title>
5426 <primary>LIKE
</primary>
5430 <replaceable>string
</replaceable> LIKE
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5431 <replaceable>string
</replaceable> NOT LIKE
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5435 The
<function>LIKE
</function> expression returns true if the
5436 <replaceable>string
</replaceable> matches the supplied
5437 <replaceable>pattern
</replaceable>. (As
5438 expected, the
<function>NOT LIKE
</function> expression returns
5439 false if
<function>LIKE
</function> returns true, and vice versa.
5440 An equivalent expression is
5441 <literal>NOT (
<replaceable>string
</replaceable> LIKE
5442 <replaceable>pattern
</replaceable>)
</literal>.)
5446 If
<replaceable>pattern
</replaceable> does not contain percent
5447 signs or underscores, then the pattern only represents the string
5448 itself; in that case
<function>LIKE
</function> acts like the
5449 equals operator. An underscore (
<literal>_
</literal>) in
5450 <replaceable>pattern
</replaceable> stands for (matches) any single
5451 character; a percent sign (
<literal>%
</literal>) matches any sequence
5452 of zero or more characters.
5458 'abc' LIKE 'abc'
<lineannotation>true
</lineannotation>
5459 'abc' LIKE 'a%'
<lineannotation>true
</lineannotation>
5460 'abc' LIKE '_b_'
<lineannotation>true
</lineannotation>
5461 'abc' LIKE 'c'
<lineannotation>false
</lineannotation>
5466 <function>LIKE
</function> pattern matching always covers the entire
5467 string. Therefore, if it's desired to match a sequence anywhere within
5468 a string, the pattern must start and end with a percent sign.
5472 To match a literal underscore or percent sign without matching
5473 other characters, the respective character in
5474 <replaceable>pattern
</replaceable> must be
5475 preceded by the escape character. The default escape
5476 character is the backslash but a different one can be selected by
5477 using the
<literal>ESCAPE
</literal> clause. To match the escape
5478 character itself, write two escape characters.
5483 If you have
<xref linkend=
"guc-standard-conforming-strings"/> turned off,
5484 any backslashes you write in literal string constants will need to be
5485 doubled. See
<xref linkend=
"sql-syntax-strings"/> for more information.
5490 It's also possible to select no escape character by writing
5491 <literal>ESCAPE ''
</literal>. This effectively disables the
5492 escape mechanism, which makes it impossible to turn off the
5493 special meaning of underscore and percent signs in the pattern.
5497 According to the SQL standard, omitting
<literal>ESCAPE
</literal>
5498 means there is no escape character (rather than defaulting to a
5499 backslash), and a zero-length
<literal>ESCAPE
</literal> value is
5500 disallowed.
<productname>PostgreSQL
</productname>'s behavior in
5501 this regard is therefore slightly nonstandard.
5505 The key word
<token>ILIKE
</token> can be used instead of
5506 <token>LIKE
</token> to make the match case-insensitive according
5507 to the active locale. This is not in the
<acronym>SQL
</acronym> standard but is a
5508 <productname>PostgreSQL
</productname> extension.
5512 The operator
<literal>~~
</literal> is equivalent to
5513 <function>LIKE
</function>, and
<literal>~~*
</literal> corresponds to
5514 <function>ILIKE
</function>. There are also
5515 <literal>!~~
</literal> and
<literal>!~~*
</literal> operators that
5516 represent
<function>NOT LIKE
</function> and
<function>NOT
5517 ILIKE
</function>, respectively. All of these operators are
5518 <productname>PostgreSQL
</productname>-specific. You may see these
5519 operator names in
<command>EXPLAIN
</command> output and similar
5520 places, since the parser actually translates
<function>LIKE
</function>
5521 et al. to these operators.
5525 The phrases
<function>LIKE
</function>,
<function>ILIKE
</function>,
5526 <function>NOT LIKE
</function>, and
<function>NOT ILIKE
</function> are
5527 generally treated as operators
5528 in
<productname>PostgreSQL
</productname> syntax; for example they can
5529 be used in
<replaceable>expression
</replaceable>
5530 <replaceable>operator
</replaceable> ANY
5531 (
<replaceable>subquery
</replaceable>) constructs, although
5532 an
<literal>ESCAPE
</literal> clause cannot be included there. In some
5533 obscure cases it may be necessary to use the underlying operator names
5538 Also see the starts-with operator
<literal>^@
</literal> and the
5539 corresponding
<function>starts_with()
</function> function, which are
5540 useful in cases where simply matching the beginning of a string is
5546 <sect2 id=
"functions-similarto-regexp">
5547 <title><function>SIMILAR TO
</function> Regular Expressions
</title>
5550 <primary>regular expression
</primary>
5551 <!-- <seealso>pattern matching</seealso> breaks index build -->
5555 <primary>SIMILAR TO
</primary>
5558 <primary>substring
</primary>
5562 <replaceable>string
</replaceable> SIMILAR TO
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5563 <replaceable>string
</replaceable> NOT SIMILAR TO
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5567 The
<function>SIMILAR TO
</function> operator returns true or
5568 false depending on whether its pattern matches the given string.
5569 It is similar to
<function>LIKE
</function>, except that it
5570 interprets the pattern using the SQL standard's definition of a
5571 regular expression. SQL regular expressions are a curious cross
5572 between
<function>LIKE
</function> notation and common (POSIX) regular
5573 expression notation.
5577 Like
<function>LIKE
</function>, the
<function>SIMILAR TO
</function>
5578 operator succeeds only if its pattern matches the entire string;
5579 this is unlike common regular expression behavior where the pattern
5580 can match any part of the string.
5582 <function>LIKE
</function>,
<function>SIMILAR TO
</function> uses
5583 <literal>_
</literal> and
<literal>%
</literal> as wildcard characters denoting
5584 any single character and any string, respectively (these are
5585 comparable to
<literal>.
</literal> and
<literal>.*
</literal> in POSIX regular
5590 In addition to these facilities borrowed from
<function>LIKE
</function>,
5591 <function>SIMILAR TO
</function> supports these pattern-matching
5592 metacharacters borrowed from POSIX regular expressions:
5597 <literal>|
</literal> denotes alternation (either of two alternatives).
5602 <literal>*
</literal> denotes repetition of the previous item zero
5608 <literal>+
</literal> denotes repetition of the previous item one
5614 <literal>?
</literal> denotes repetition of the previous item zero
5620 <literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal> denotes repetition
5621 of the previous item exactly
<replaceable>m
</replaceable> times.
5626 <literal>{
</literal><replaceable>m
</replaceable><literal>,}
</literal> denotes repetition
5627 of the previous item
<replaceable>m
</replaceable> or more times.
5632 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal>
5633 denotes repetition of the previous item at least
<replaceable>m
</replaceable> and
5634 not more than
<replaceable>n
</replaceable> times.
5639 Parentheses
<literal>()
</literal> can be used to group items into
5640 a single logical item.
5645 A bracket expression
<literal>[...]
</literal> specifies a character
5646 class, just as in POSIX regular expressions.
5651 Notice that the period (
<literal>.
</literal>) is not a metacharacter
5652 for
<function>SIMILAR TO
</function>.
5656 As with
<function>LIKE
</function>, a backslash disables the special
5657 meaning of any of these metacharacters. A different escape character
5658 can be specified with
<literal>ESCAPE
</literal>, or the escape
5659 capability can be disabled by writing
<literal>ESCAPE ''
</literal>.
5663 According to the SQL standard, omitting
<literal>ESCAPE
</literal>
5664 means there is no escape character (rather than defaulting to a
5665 backslash), and a zero-length
<literal>ESCAPE
</literal> value is
5666 disallowed.
<productname>PostgreSQL
</productname>'s behavior in
5667 this regard is therefore slightly nonstandard.
5671 Another nonstandard extension is that following the escape character
5672 with a letter or digit provides access to the escape sequences
5673 defined for POSIX regular expressions; see
5674 <xref linkend=
"posix-character-entry-escapes-table"/>,
5675 <xref linkend=
"posix-class-shorthand-escapes-table"/>, and
5676 <xref linkend=
"posix-constraint-escapes-table"/> below.
5682 'abc' SIMILAR TO 'abc'
<lineannotation>true
</lineannotation>
5683 'abc' SIMILAR TO 'a'
<lineannotation>false
</lineannotation>
5684 'abc' SIMILAR TO '%(b|d)%'
<lineannotation>true
</lineannotation>
5685 'abc' SIMILAR TO '(b|c)%'
<lineannotation>false
</lineannotation>
5686 '-abc-' SIMILAR TO '%\mabc\M%'
<lineannotation>true
</lineannotation>
5687 'xabcy' SIMILAR TO '%\mabc\M%'
<lineannotation>false
</lineannotation>
5692 The
<function>substring
</function> function with three parameters
5693 provides extraction of a substring that matches an SQL
5694 regular expression pattern. The function can be written according
5695 to standard SQL syntax:
5697 substring(
<replaceable>string
</replaceable> similar
<replaceable>pattern
</replaceable> escape
<replaceable>escape-character
</replaceable>)
5699 or using the now obsolete SQL:
1999 syntax:
5701 substring(
<replaceable>string
</replaceable> from
<replaceable>pattern
</replaceable> for
<replaceable>escape-character
</replaceable>)
5703 or as a plain three-argument function:
5705 substring(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>,
<replaceable>escape-character
</replaceable>)
5707 As with
<literal>SIMILAR TO
</literal>, the
5708 specified pattern must match the entire data string, or else the
5709 function fails and returns null. To indicate the part of the
5710 pattern for which the matching data sub-string is of interest,
5711 the pattern should contain
5712 two occurrences of the escape character followed by a double quote
5713 (
<literal>"</literal>). <!-- " font-lock sanity -->
5714 The text matching the portion of the pattern
5715 between these separators is returned when the match is successful.
5719 The escape-double-quote separators actually
5720 divide
<function>substring
</function>'s pattern into three independent
5721 regular expressions; for example, a vertical bar (
<literal>|
</literal>)
5722 in any of the three sections affects only that section. Also, the first
5723 and third of these regular expressions are defined to match the smallest
5724 possible amount of text, not the largest, when there is any ambiguity
5725 about how much of the data string matches which pattern. (In POSIX
5726 parlance, the first and third regular expressions are forced to be
5731 As an extension to the SQL standard,
<productname>PostgreSQL
</productname>
5732 allows there to be just one escape-double-quote separator, in which case
5733 the third regular expression is taken as empty; or no separators, in which
5734 case the first and third regular expressions are taken as empty.
5738 Some examples, with
<literal>#
"</literal> delimiting the return string:
5740 substring('foobar' similar '%#
"o_b#"%' escape '#')
<lineannotation>oob
</lineannotation>
5741 substring('foobar' similar '#
"o_b#"%' escape '#')
<lineannotation>NULL
</lineannotation>
5746 <sect2 id=
"functions-posix-regexp">
5747 <title><acronym>POSIX
</acronym> Regular Expressions
</title>
5749 <indexterm zone=
"functions-posix-regexp">
5750 <primary>regular expression
</primary>
5751 <seealso>pattern matching
</seealso>
5754 <primary>substring
</primary>
5757 <primary>regexp_count
</primary>
5760 <primary>regexp_instr
</primary>
5763 <primary>regexp_like
</primary>
5766 <primary>regexp_match
</primary>
5769 <primary>regexp_matches
</primary>
5772 <primary>regexp_replace
</primary>
5775 <primary>regexp_split_to_table
</primary>
5778 <primary>regexp_split_to_array
</primary>
5781 <primary>regexp_substr
</primary>
5785 <xref linkend=
"functions-posix-table"/> lists the available
5786 operators for pattern matching using POSIX regular expressions.
5789 <table id=
"functions-posix-table">
5790 <title>Regular Expression Match Operators
</title>
5795 <entry role=
"func_table_entry"><para role=
"func_signature">
5809 <entry role=
"func_table_entry"><para role=
"func_signature">
5810 <type>text
</type> <literal>~
</literal> <type>text
</type>
5811 <returnvalue>boolean
</returnvalue>
5814 String matches regular expression, case sensitively
5817 <literal>'thomas' ~ 't.*ma'
</literal>
5818 <returnvalue>t
</returnvalue>
5823 <entry role=
"func_table_entry"><para role=
"func_signature">
5824 <type>text
</type> <literal>~*
</literal> <type>text
</type>
5825 <returnvalue>boolean
</returnvalue>
5828 String matches regular expression, case-insensitively
5831 <literal>'thomas' ~* 'T.*ma'
</literal>
5832 <returnvalue>t
</returnvalue>
5837 <entry role=
"func_table_entry"><para role=
"func_signature">
5838 <type>text
</type> <literal>!~
</literal> <type>text
</type>
5839 <returnvalue>boolean
</returnvalue>
5842 String does not match regular expression, case sensitively
5845 <literal>'thomas' !~ 't.*max'
</literal>
5846 <returnvalue>t
</returnvalue>
5851 <entry role=
"func_table_entry"><para role=
"func_signature">
5852 <type>text
</type> <literal>!~*
</literal> <type>text
</type>
5853 <returnvalue>boolean
</returnvalue>
5856 String does not match regular expression, case-insensitively
5859 <literal>'thomas' !~* 'T.*ma'
</literal>
5860 <returnvalue>f
</returnvalue>
5868 <acronym>POSIX
</acronym> regular expressions provide a more
5869 powerful means for pattern matching than the
<function>LIKE
</function> and
5870 <function>SIMILAR TO
</function> operators.
5871 Many Unix tools such as
<command>egrep
</command>,
5872 <command>sed
</command>, or
<command>awk
</command> use a pattern
5873 matching language that is similar to the one described here.
5877 A regular expression is a character sequence that is an
5878 abbreviated definition of a set of strings (a
<firstterm>regular
5879 set
</firstterm>). A string is said to match a regular expression
5880 if it is a member of the regular set described by the regular
5881 expression. As with
<function>LIKE
</function>, pattern characters
5882 match string characters exactly unless they are special characters
5883 in the regular expression language
— but regular expressions use
5884 different special characters than
<function>LIKE
</function> does.
5885 Unlike
<function>LIKE
</function> patterns, a
5886 regular expression is allowed to match anywhere within a string, unless
5887 the regular expression is explicitly anchored to the beginning or
5894 'abcd' ~ 'bc'
<lineannotation>true
</lineannotation>
5895 'abcd' ~ 'a.c'
<lineannotation>true
— dot matches any character
</lineannotation>
5896 'abcd' ~ 'a.*d'
<lineannotation>true
— <literal>*
</literal> repeats the preceding pattern item
</lineannotation>
5897 'abcd' ~ '(b|x)'
<lineannotation>true
— <literal>|
</literal> means OR, parentheses group
</lineannotation>
5898 'abcd' ~ '^a'
<lineannotation>true
— <literal>^
</literal> anchors to start of string
</lineannotation>
5899 'abcd' ~ '^(b|c)'
<lineannotation>false
— would match except for anchoring
</lineannotation>
5904 The
<acronym>POSIX
</acronym> pattern language is described in much
5905 greater detail below.
5909 The
<function>substring
</function> function with two parameters,
5910 <function>substring(
<replaceable>string
</replaceable> from
5911 <replaceable>pattern
</replaceable>)
</function>, provides extraction of a
5913 that matches a POSIX regular expression pattern. It returns null if
5914 there is no match, otherwise the first portion of the text that matched the
5915 pattern. But if the pattern contains any parentheses, the portion
5916 of the text that matched the first parenthesized subexpression (the
5917 one whose left parenthesis comes first) is
5918 returned. You can put parentheses around the whole expression
5919 if you want to use parentheses within it without triggering this
5920 exception. If you need parentheses in the pattern before the
5921 subexpression you want to extract, see the non-capturing parentheses
5928 substring('foobar' from 'o.b')
<lineannotation>oob
</lineannotation>
5929 substring('foobar' from 'o(.)b')
<lineannotation>o
</lineannotation>
5934 The
<function>regexp_count
</function> function counts the number of
5935 places where a POSIX regular expression pattern matches a string.
5937 <function>regexp_count
</function>(
<replaceable>string
</replaceable>,
5938 <replaceable>pattern
</replaceable>
5939 <optional>,
<replaceable>start
</replaceable>
5940 <optional>,
<replaceable>flags
</replaceable>
5941 </optional></optional>).
5942 <replaceable>pattern
</replaceable> is searched for
5943 in
<replaceable>string
</replaceable>, normally from the beginning of
5944 the string, but if the
<replaceable>start
</replaceable> parameter is
5945 provided then beginning from that character index.
5946 The
<replaceable>flags
</replaceable> parameter is an optional text
5947 string containing zero or more single-letter flags that change the
5948 function's behavior. For example, including
<literal>i
</literal> in
5949 <replaceable>flags
</replaceable> specifies case-insensitive matching.
5950 Supported flags are described in
5951 <xref linkend=
"posix-embedded-options-table"/>.
5957 regexp_count('ABCABCAXYaxy', 'A.')
<lineannotation>3</lineannotation>
5958 regexp_count('ABCABCAXYaxy', 'A.',
1, 'i')
<lineannotation>4</lineannotation>
5963 The
<function>regexp_instr
</function> function returns the starting or
5964 ending position of the
<replaceable>N
</replaceable>'th match of a
5965 POSIX regular expression pattern to a string, or zero if there is no
5966 such match. It has the syntax
5967 <function>regexp_instr
</function>(
<replaceable>string
</replaceable>,
5968 <replaceable>pattern
</replaceable>
5969 <optional>,
<replaceable>start
</replaceable>
5970 <optional>,
<replaceable>N
</replaceable>
5971 <optional>,
<replaceable>endoption
</replaceable>
5972 <optional>,
<replaceable>flags
</replaceable>
5973 <optional>,
<replaceable>subexpr
</replaceable>
5974 </optional></optional></optional></optional></optional>).
5975 <replaceable>pattern
</replaceable> is searched for
5976 in
<replaceable>string
</replaceable>, normally from the beginning of
5977 the string, but if the
<replaceable>start
</replaceable> parameter is
5978 provided then beginning from that character index.
5979 If
<replaceable>N
</replaceable> is specified
5980 then the
<replaceable>N
</replaceable>'th match of the pattern
5981 is located, otherwise the first match is located.
5982 If the
<replaceable>endoption
</replaceable> parameter is omitted or
5983 specified as zero, the function returns the position of the first
5984 character of the match. Otherwise,
<replaceable>endoption
</replaceable>
5985 must be one, and the function returns the position of the character
5986 following the match.
5987 The
<replaceable>flags
</replaceable> parameter is an optional text
5988 string containing zero or more single-letter flags that change the
5989 function's behavior. Supported flags are described
5990 in
<xref linkend=
"posix-embedded-options-table"/>.
5991 For a pattern containing parenthesized
5992 subexpressions,
<replaceable>subexpr
</replaceable> is an integer
5993 indicating which subexpression is of interest: the result identifies
5994 the position of the substring matching that subexpression.
5995 Subexpressions are numbered in the order of their leading parentheses.
5996 When
<replaceable>subexpr
</replaceable> is omitted or zero, the result
5997 identifies the position of the whole match regardless of
5998 parenthesized subexpressions.
6004 regexp_instr('number of your street, town zip, FR', '[^,]+',
1,
2)
6005 <lineannotation>23</lineannotation>
6006 regexp_instr(string=
>'ABCDEFGHI', pattern=
>'(c..)(...)', start=
>1,
"N"=
>1, endoption=
>0, flags=
>'i', subexpr=
>2)
6007 <lineannotation>6</lineannotation>
6012 The
<function>regexp_like
</function> function checks whether a match
6013 of a POSIX regular expression pattern occurs within a string,
6014 returning boolean true or false. It has the syntax
6015 <function>regexp_like
</function>(
<replaceable>string
</replaceable>,
6016 <replaceable>pattern
</replaceable>
6017 <optional>,
<replaceable>flags
</replaceable> </optional>).
6018 The
<replaceable>flags
</replaceable> parameter is an optional text
6019 string containing zero or more single-letter flags that change the
6020 function's behavior. Supported flags are described
6021 in
<xref linkend=
"posix-embedded-options-table"/>.
6022 This function has the same results as the
<literal>~
</literal>
6023 operator if no flags are specified. If only the
<literal>i
</literal>
6024 flag is specified, it has the same results as
6025 the
<literal>~*
</literal> operator.
6031 regexp_like('Hello World', 'world')
<lineannotation>false
</lineannotation>
6032 regexp_like('Hello World', 'world', 'i')
<lineannotation>true
</lineannotation>
6037 The
<function>regexp_match
</function> function returns a text array of
6038 matching substring(s) within the first match of a POSIX
6039 regular expression pattern to a string. It has the syntax
6040 <function>regexp_match
</function>(
<replaceable>string
</replaceable>,
6041 <replaceable>pattern
</replaceable> <optional>,
<replaceable>flags
</replaceable> </optional>).
6042 If there is no match, the result is
<literal>NULL
</literal>.
6043 If a match is found, and the
<replaceable>pattern
</replaceable> contains no
6044 parenthesized subexpressions, then the result is a single-element text
6045 array containing the substring matching the whole pattern.
6046 If a match is found, and the
<replaceable>pattern
</replaceable> contains
6047 parenthesized subexpressions, then the result is a text array
6048 whose
<replaceable>n
</replaceable>'th element is the substring matching
6049 the
<replaceable>n
</replaceable>'th parenthesized subexpression of
6050 the
<replaceable>pattern
</replaceable> (not counting
<quote>non-capturing
</quote>
6051 parentheses; see below for details).
6052 The
<replaceable>flags
</replaceable> parameter is an optional text string
6053 containing zero or more single-letter flags that change the function's
6054 behavior. Supported flags are described
6055 in
<xref linkend=
"posix-embedded-options-table"/>.
6061 SELECT regexp_match('foobarbequebaz', 'bar.*que');
6067 SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
6077 In the common case where you just want the whole matching substring
6078 or
<literal>NULL
</literal> for no match, the best solution is to
6079 use
<function>regexp_substr()
</function>.
6080 However,
<function>regexp_substr()
</function> only exists
6081 in
<productname>PostgreSQL
</productname> version
15 and up. When
6082 working in older versions, you can extract the first element
6083 of
<function>regexp_match()
</function>'s result, for example:
6085 SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[
1];
6095 The
<function>regexp_matches
</function> function returns a set of text arrays
6096 of matching substring(s) within matches of a POSIX regular
6097 expression pattern to a string. It has the same syntax as
6098 <function>regexp_match
</function>.
6099 This function returns no rows if there is no match, one row if there is
6100 a match and the
<literal>g
</literal> flag is not given, or
<replaceable>N
</replaceable>
6101 rows if there are
<replaceable>N
</replaceable> matches and the
<literal>g
</literal> flag
6102 is given. Each returned row is a text array containing the whole
6103 matched substring or the substrings matching parenthesized
6104 subexpressions of the
<replaceable>pattern
</replaceable>, just as described above
6105 for
<function>regexp_match
</function>.
6106 <function>regexp_matches
</function> accepts all the flags shown
6107 in
<xref linkend=
"posix-embedded-options-table"/>, plus
6108 the
<literal>g
</literal> flag which commands it to return all matches, not
6115 SELECT regexp_matches('foo', 'not there');
6120 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
6131 In most cases
<function>regexp_matches()
</function> should be used with
6132 the
<literal>g
</literal> flag, since if you only want the first match, it's
6133 easier and more efficient to use
<function>regexp_match()
</function>.
6134 However,
<function>regexp_match()
</function> only exists
6135 in
<productname>PostgreSQL
</productname> version
10 and up. When working in older
6136 versions, a common trick is to place a
<function>regexp_matches()
</function>
6137 call in a sub-select, for example:
6139 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
6141 This produces a text array if there's a match, or
<literal>NULL
</literal> if
6142 not, the same as
<function>regexp_match()
</function> would do. Without the
6143 sub-select, this query would produce no output at all for table rows
6144 without a match, which is typically not the desired behavior.
6149 The
<function>regexp_replace
</function> function provides substitution of
6150 new text for substrings that match POSIX regular expression patterns.
6152 <function>regexp_replace
</function>(
<replaceable>string
</replaceable>,
6153 <replaceable>pattern
</replaceable>,
<replaceable>replacement
</replaceable>
6154 <optional>,
<replaceable>flags
</replaceable> </optional>)
6156 <function>regexp_replace
</function>(
<replaceable>string
</replaceable>,
6157 <replaceable>pattern
</replaceable>,
<replaceable>replacement
</replaceable>,
6158 <replaceable>start
</replaceable>
6159 <optional>,
<replaceable>N
</replaceable>
6160 <optional>,
<replaceable>flags
</replaceable> </optional></optional>).
6161 The source
<replaceable>string
</replaceable> is returned unchanged if
6162 there is no match to the
<replaceable>pattern
</replaceable>. If there is a
6163 match, the
<replaceable>string
</replaceable> is returned with the
6164 <replaceable>replacement
</replaceable> string substituted for the matching
6165 substring. The
<replaceable>replacement
</replaceable> string can contain
6166 <literal>\
</literal><replaceable>n
</replaceable>, where
<replaceable>n
</replaceable> is
1
6167 through
9, to indicate that the source substring matching the
6168 <replaceable>n
</replaceable>'th parenthesized subexpression of the pattern should be
6169 inserted, and it can contain
<literal>\
&</literal> to indicate that the
6170 substring matching the entire pattern should be inserted. Write
6171 <literal>\\
</literal> if you need to put a literal backslash in the replacement
6173 <replaceable>pattern
</replaceable> is searched for
6174 in
<replaceable>string
</replaceable>, normally from the beginning of
6175 the string, but if the
<replaceable>start
</replaceable> parameter is
6176 provided then beginning from that character index.
6177 By default, only the first match of the pattern is replaced.
6178 If
<replaceable>N
</replaceable> is specified and is greater than zero,
6179 then the
<replaceable>N
</replaceable>'th match of the pattern
6181 If the
<literal>g
</literal> flag is given, or
6182 if
<replaceable>N
</replaceable> is specified and is zero, then all
6183 matches at or after the
<replaceable>start
</replaceable> position are
6184 replaced. (The
<literal>g
</literal> flag is ignored
6185 when
<replaceable>N
</replaceable> is specified.)
6186 The
<replaceable>flags
</replaceable> parameter is an optional text
6187 string containing zero or more single-letter flags that change the
6188 function's behavior. Supported flags (though
6189 not
<literal>g
</literal>) are
6190 described in
<xref linkend=
"posix-embedded-options-table"/>.
6196 regexp_replace('foobarbaz', 'b..', 'X')
6197 <lineannotation>fooXbaz
</lineannotation>
6198 regexp_replace('foobarbaz', 'b..', 'X', 'g')
6199 <lineannotation>fooXX
</lineannotation>
6200 regexp_replace('foobarbaz', 'b(..)', 'X\
1Y', 'g')
6201 <lineannotation>fooXarYXazY
</lineannotation>
6202 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X',
1,
0, 'i')
6203 <lineannotation>X PXstgrXSQL fXnctXXn
</lineannotation>
6204 regexp_replace(string=
>'A PostgreSQL function', pattern=
>'a|e|i|o|u', replacement=
>'X', start=
>1,
"N"=
>3, flags=
>'i')
6205 <lineannotation>A PostgrXSQL function
</lineannotation>
6210 The
<function>regexp_split_to_table
</function> function splits a string using a POSIX
6211 regular expression pattern as a delimiter. It has the syntax
6212 <function>regexp_split_to_table
</function>(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>
6213 <optional>,
<replaceable>flags
</replaceable> </optional>).
6214 If there is no match to the
<replaceable>pattern
</replaceable>, the function returns the
6215 <replaceable>string
</replaceable>. If there is at least one match, for each match it returns
6216 the text from the end of the last match (or the beginning of the string)
6217 to the beginning of the match. When there are no more matches, it
6218 returns the text from the end of the last match to the end of the string.
6219 The
<replaceable>flags
</replaceable> parameter is an optional text string containing
6220 zero or more single-letter flags that change the function's behavior.
6221 <function>regexp_split_to_table
</function> supports the flags described in
6222 <xref linkend=
"posix-embedded-options-table"/>.
6226 The
<function>regexp_split_to_array
</function> function behaves the same as
6227 <function>regexp_split_to_table
</function>, except that
<function>regexp_split_to_array
</function>
6228 returns its result as an array of
<type>text
</type>. It has the syntax
6229 <function>regexp_split_to_array
</function>(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>
6230 <optional>,
<replaceable>flags
</replaceable> </optional>).
6231 The parameters are the same as for
<function>regexp_split_to_table
</function>.
6237 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo;
6251 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+');
6252 regexp_split_to_array
6253 -----------------------------------------------
6254 {the,quick,brown,fox,jumps,over,the,lazy,dog}
6257 SELECT foo FROM regexp_split_to_table('the quick brown fox', '\s*') AS foo;
6281 As the last example demonstrates, the regexp split functions ignore
6282 zero-length matches that occur at the start or end of the string
6283 or immediately after a previous match. This is contrary to the strict
6284 definition of regexp matching that is implemented by
6285 the other regexp functions, but is usually the most convenient behavior
6286 in practice. Other software systems such as Perl use similar definitions.
6290 The
<function>regexp_substr
</function> function returns the substring
6291 that matches a POSIX regular expression pattern,
6292 or
<literal>NULL
</literal> if there is no match. It has the syntax
6293 <function>regexp_substr
</function>(
<replaceable>string
</replaceable>,
6294 <replaceable>pattern
</replaceable>
6295 <optional>,
<replaceable>start
</replaceable>
6296 <optional>,
<replaceable>N
</replaceable>
6297 <optional>,
<replaceable>flags
</replaceable>
6298 <optional>,
<replaceable>subexpr
</replaceable>
6299 </optional></optional></optional></optional>).
6300 <replaceable>pattern
</replaceable> is searched for
6301 in
<replaceable>string
</replaceable>, normally from the beginning of
6302 the string, but if the
<replaceable>start
</replaceable> parameter is
6303 provided then beginning from that character index.
6304 If
<replaceable>N
</replaceable> is specified
6305 then the
<replaceable>N
</replaceable>'th match of the pattern
6306 is returned, otherwise the first match is returned.
6307 The
<replaceable>flags
</replaceable> parameter is an optional text
6308 string containing zero or more single-letter flags that change the
6309 function's behavior. Supported flags are described
6310 in
<xref linkend=
"posix-embedded-options-table"/>.
6311 For a pattern containing parenthesized
6312 subexpressions,
<replaceable>subexpr
</replaceable> is an integer
6313 indicating which subexpression is of interest: the result is the
6314 substring matching that subexpression.
6315 Subexpressions are numbered in the order of their leading parentheses.
6316 When
<replaceable>subexpr
</replaceable> is omitted or zero, the result
6317 is the whole match regardless of parenthesized subexpressions.
6323 regexp_substr('number of your street, town zip, FR', '[^,]+',
1,
2)
6324 <lineannotation> town zip
</lineannotation>
6325 regexp_substr('ABCDEFGHI', '(c..)(...)',
1,
1, 'i',
2)
6326 <lineannotation>FGH
</lineannotation>
6330 <!-- derived from the re_syntax.n man page -->
6332 <sect3 id=
"posix-syntax-details">
6333 <title>Regular Expression Details
</title>
6336 <productname>PostgreSQL
</productname>'s regular expressions are implemented
6337 using a software package written by Henry Spencer. Much of
6338 the description of regular expressions below is copied verbatim from his
6343 Regular expressions (
<acronym>RE
</acronym>s), as defined in
6344 <acronym>POSIX
</acronym> 1003.2, come in two forms:
6345 <firstterm>extended
</firstterm> <acronym>RE
</acronym>s or
<acronym>ERE
</acronym>s
6346 (roughly those of
<command>egrep
</command>), and
6347 <firstterm>basic
</firstterm> <acronym>RE
</acronym>s or
<acronym>BRE
</acronym>s
6348 (roughly those of
<command>ed
</command>).
6349 <productname>PostgreSQL
</productname> supports both forms, and
6350 also implements some extensions
6351 that are not in the POSIX standard, but have become widely used
6352 due to their availability in programming languages such as Perl and Tcl.
6353 <acronym>RE
</acronym>s using these non-POSIX extensions are called
6354 <firstterm>advanced
</firstterm> <acronym>RE
</acronym>s or
<acronym>ARE
</acronym>s
6355 in this documentation. AREs are almost an exact superset of EREs,
6356 but BREs have several notational incompatibilities (as well as being
6358 We first describe the ARE and ERE forms, noting features that apply
6359 only to AREs, and then describe how BREs differ.
6364 <productname>PostgreSQL
</productname> always initially presumes that a regular
6365 expression follows the ARE rules. However, the more limited ERE or
6366 BRE rules can be chosen by prepending an
<firstterm>embedded option
</firstterm>
6367 to the RE pattern, as described in
<xref linkend=
"posix-metasyntax"/>.
6368 This can be useful for compatibility with applications that expect
6369 exactly the
<acronym>POSIX
</acronym> 1003.2 rules.
6374 A regular expression is defined as one or more
6375 <firstterm>branches
</firstterm>, separated by
6376 <literal>|
</literal>. It matches anything that matches one of the
6381 A branch is zero or more
<firstterm>quantified atoms
</firstterm> or
6382 <firstterm>constraints
</firstterm>, concatenated.
6383 It matches a match for the first, followed by a match for the second, etc.;
6384 an empty branch matches the empty string.
6388 A quantified atom is an
<firstterm>atom
</firstterm> possibly followed
6389 by a single
<firstterm>quantifier
</firstterm>.
6390 Without a quantifier, it matches a match for the atom.
6391 With a quantifier, it can match some number of matches of the atom.
6392 An
<firstterm>atom
</firstterm> can be any of the possibilities
6393 shown in
<xref linkend=
"posix-atoms-table"/>.
6394 The possible quantifiers and their meanings are shown in
6395 <xref linkend=
"posix-quantifiers-table"/>.
6399 A
<firstterm>constraint
</firstterm> matches an empty string, but matches only when
6400 specific conditions are met. A constraint can be used where an atom
6401 could be used, except it cannot be followed by a quantifier.
6402 The simple constraints are shown in
6403 <xref linkend=
"posix-constraints-table"/>;
6404 some more constraints are described later.
6408 <table id=
"posix-atoms-table">
6409 <title>Regular Expression Atoms
</title>
6415 <entry>Description
</entry>
6421 <entry> <literal>(
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6422 <entry> (where
<replaceable>re
</replaceable> is any regular expression)
6424 <replaceable>re
</replaceable>, with the match noted for possible reporting
</entry>
6428 <entry> <literal>(?:
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6429 <entry> as above, but the match is not noted for reporting
6430 (a
<quote>non-capturing
</quote> set of parentheses)
6431 (AREs only)
</entry>
6435 <entry> <literal>.
</literal> </entry>
6436 <entry> matches any single character
</entry>
6440 <entry> <literal>[
</literal><replaceable>chars
</replaceable><literal>]
</literal> </entry>
6441 <entry> a
<firstterm>bracket expression
</firstterm>,
6442 matching any one of the
<replaceable>chars
</replaceable> (see
6443 <xref linkend=
"posix-bracket-expressions"/> for more detail)
</entry>
6447 <entry> <literal>\
</literal><replaceable>k
</replaceable> </entry>
6448 <entry> (where
<replaceable>k
</replaceable> is a non-alphanumeric character)
6449 matches that character taken as an ordinary character,
6450 e.g.,
<literal>\\
</literal> matches a backslash character
</entry>
6454 <entry> <literal>\
</literal><replaceable>c
</replaceable> </entry>
6455 <entry> where
<replaceable>c
</replaceable> is alphanumeric
6456 (possibly followed by other characters)
6457 is an
<firstterm>escape
</firstterm>, see
<xref linkend=
"posix-escape-sequences"/>
6458 (AREs only; in EREs and BREs, this matches
<replaceable>c
</replaceable>)
</entry>
6462 <entry> <literal>{
</literal> </entry>
6463 <entry> when followed by a character other than a digit,
6464 matches the left-brace character
<literal>{
</literal>;
6465 when followed by a digit, it is the beginning of a
6466 <replaceable>bound
</replaceable> (see below)
</entry>
6470 <entry> <replaceable>x
</replaceable> </entry>
6471 <entry> where
<replaceable>x
</replaceable> is a single character with no other
6472 significance, matches that character
</entry>
6479 An RE cannot end with a backslash (
<literal>\
</literal>).
6484 If you have
<xref linkend=
"guc-standard-conforming-strings"/> turned off,
6485 any backslashes you write in literal string constants will need to be
6486 doubled. See
<xref linkend=
"sql-syntax-strings"/> for more information.
6490 <table id=
"posix-quantifiers-table">
6491 <title>Regular Expression Quantifiers
</title>
6496 <entry>Quantifier
</entry>
6497 <entry>Matches
</entry>
6503 <entry> <literal>*
</literal> </entry>
6504 <entry> a sequence of
0 or more matches of the atom
</entry>
6508 <entry> <literal>+
</literal> </entry>
6509 <entry> a sequence of
1 or more matches of the atom
</entry>
6513 <entry> <literal>?
</literal> </entry>
6514 <entry> a sequence of
0 or
1 matches of the atom
</entry>
6518 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal> </entry>
6519 <entry> a sequence of exactly
<replaceable>m
</replaceable> matches of the atom
</entry>
6523 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>,}
</literal> </entry>
6524 <entry> a sequence of
<replaceable>m
</replaceable> or more matches of the atom
</entry>
6529 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal> </entry>
6530 <entry> a sequence of
<replaceable>m
</replaceable> through
<replaceable>n
</replaceable>
6531 (inclusive) matches of the atom;
<replaceable>m
</replaceable> cannot exceed
6532 <replaceable>n
</replaceable> </entry>
6536 <entry> <literal>*?
</literal> </entry>
6537 <entry> non-greedy version of
<literal>*
</literal> </entry>
6541 <entry> <literal>+?
</literal> </entry>
6542 <entry> non-greedy version of
<literal>+
</literal> </entry>
6546 <entry> <literal>??
</literal> </entry>
6547 <entry> non-greedy version of
<literal>?
</literal> </entry>
6551 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>}?
</literal> </entry>
6552 <entry> non-greedy version of
<literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal> </entry>
6556 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>,}?
</literal> </entry>
6557 <entry> non-greedy version of
<literal>{
</literal><replaceable>m
</replaceable><literal>,}
</literal> </entry>
6562 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}?
</literal> </entry>
6563 <entry> non-greedy version of
<literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal> </entry>
6570 The forms using
<literal>{
</literal><replaceable>...
</replaceable><literal>}
</literal>
6571 are known as
<firstterm>bounds
</firstterm>.
6572 The numbers
<replaceable>m
</replaceable> and
<replaceable>n
</replaceable> within a bound are
6573 unsigned decimal integers with permissible values from
0 to
255 inclusive.
6577 <firstterm>Non-greedy
</firstterm> quantifiers (available in AREs only) match the
6578 same possibilities as their corresponding normal (
<firstterm>greedy
</firstterm>)
6579 counterparts, but prefer the smallest number rather than the largest
6581 See
<xref linkend=
"posix-matching-rules"/> for more detail.
6586 A quantifier cannot immediately follow another quantifier, e.g.,
6587 <literal>**
</literal> is invalid.
6589 begin an expression or subexpression or follow
6590 <literal>^
</literal> or
<literal>|
</literal>.
6594 <table id=
"posix-constraints-table">
6595 <title>Regular Expression Constraints
</title>
6600 <entry>Constraint
</entry>
6601 <entry>Description
</entry>
6607 <entry> <literal>^
</literal> </entry>
6608 <entry> matches at the beginning of the string
</entry>
6612 <entry> <literal>$
</literal> </entry>
6613 <entry> matches at the end of the string
</entry>
6617 <entry> <literal>(?=
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6618 <entry> <firstterm>positive lookahead
</firstterm> matches at any point
6619 where a substring matching
<replaceable>re
</replaceable> begins
6620 (AREs only)
</entry>
6624 <entry> <literal>(?!
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6625 <entry> <firstterm>negative lookahead
</firstterm> matches at any point
6626 where no substring matching
<replaceable>re
</replaceable> begins
6627 (AREs only)
</entry>
6631 <entry> <literal>(?
<=
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6632 <entry> <firstterm>positive lookbehind
</firstterm> matches at any point
6633 where a substring matching
<replaceable>re
</replaceable> ends
6634 (AREs only)
</entry>
6638 <entry> <literal>(?
<!
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6639 <entry> <firstterm>negative lookbehind
</firstterm> matches at any point
6640 where no substring matching
<replaceable>re
</replaceable> ends
6641 (AREs only)
</entry>
6648 Lookahead and lookbehind constraints cannot contain
<firstterm>back
6649 references
</firstterm> (see
<xref linkend=
"posix-escape-sequences"/>),
6650 and all parentheses within them are considered non-capturing.
6654 <sect3 id=
"posix-bracket-expressions">
6655 <title>Bracket Expressions
</title>
6658 A
<firstterm>bracket expression
</firstterm> is a list of
6659 characters enclosed in
<literal>[]
</literal>. It normally matches
6660 any single character from the list (but see below). If the list
6661 begins with
<literal>^
</literal>, it matches any single character
6662 <emphasis>not
</emphasis> from the rest of the list.
6664 in the list are separated by
<literal>-
</literal>, this is
6665 shorthand for the full range of characters between those two
6666 (inclusive) in the collating sequence,
6667 e.g.,
<literal>[
0-
9]
</literal> in
<acronym>ASCII
</acronym> matches
6668 any decimal digit. It is illegal for two ranges to share an
6669 endpoint, e.g.,
<literal>a-c-e
</literal>. Ranges are very
6670 collating-sequence-dependent, so portable programs should avoid
6675 To include a literal
<literal>]
</literal> in the list, make it the
6676 first character (after
<literal>^
</literal>, if that is used). To
6677 include a literal
<literal>-
</literal>, make it the first or last
6678 character, or the second endpoint of a range. To use a literal
6679 <literal>-
</literal> as the first endpoint of a range, enclose it
6680 in
<literal>[.
</literal> and
<literal>.]
</literal> to make it a
6681 collating element (see below). With the exception of these characters,
6682 some combinations using
<literal>[
</literal>
6683 (see next paragraphs), and escapes (AREs only), all other special
6684 characters lose their special significance within a bracket expression.
6685 In particular,
<literal>\
</literal> is not special when following
6686 ERE or BRE rules, though it is special (as introducing an escape)
6691 Within a bracket expression, a collating element (a character, a
6692 multiple-character sequence that collates as if it were a single
6693 character, or a collating-sequence name for either) enclosed in
6694 <literal>[.
</literal> and
<literal>.]
</literal> stands for the
6695 sequence of characters of that collating element. The sequence is
6696 treated as a single element of the bracket expression's list. This
6698 expression containing a multiple-character collating element to
6699 match more than one character, e.g., if the collating sequence
6700 includes a
<literal>ch
</literal> collating element, then the RE
6701 <literal>[[.ch.]]*c
</literal> matches the first five characters of
6702 <literal>chchcc
</literal>.
6707 <productname>PostgreSQL
</productname> currently does not support multi-character collating
6708 elements. This information describes possible future behavior.
6713 Within a bracket expression, a collating element enclosed in
6714 <literal>[=
</literal> and
<literal>=]
</literal> is an
<firstterm>equivalence
6715 class
</firstterm>, standing for the sequences of characters of all collating
6716 elements equivalent to that one, including itself. (If there are
6717 no other equivalent collating elements, the treatment is as if the
6718 enclosing delimiters were
<literal>[.
</literal> and
6719 <literal>.]
</literal>.) For example, if
<literal>o
</literal> and
6720 <literal>^
</literal> are the members of an equivalence class, then
6721 <literal>[[=o=]]
</literal>,
<literal>[[=^=]]
</literal>, and
6722 <literal>[o^]
</literal> are all synonymous. An equivalence class
6723 cannot be an endpoint of a range.
6727 Within a bracket expression, the name of a character class
6728 enclosed in
<literal>[:
</literal> and
<literal>:]
</literal> stands
6729 for the list of all characters belonging to that class. A character
6730 class cannot be used as an endpoint of a range.
6731 The
<acronym>POSIX
</acronym> standard defines these character class
6733 <literal>alnum
</literal> (letters and numeric digits),
6734 <literal>alpha
</literal> (letters),
6735 <literal>blank
</literal> (space and tab),
6736 <literal>cntrl
</literal> (control characters),
6737 <literal>digit
</literal> (numeric digits),
6738 <literal>graph
</literal> (printable characters except space),
6739 <literal>lower
</literal> (lower-case letters),
6740 <literal>print
</literal> (printable characters including space),
6741 <literal>punct
</literal> (punctuation),
6742 <literal>space
</literal> (any white space),
6743 <literal>upper
</literal> (upper-case letters),
6744 and
<literal>xdigit
</literal> (hexadecimal digits).
6745 The behavior of these standard character classes is generally
6746 consistent across platforms for characters in the
7-bit ASCII set.
6747 Whether a given non-ASCII character is considered to belong to one
6748 of these classes depends on the
<firstterm>collation
</firstterm>
6749 that is used for the regular-expression function or operator
6750 (see
<xref linkend=
"collation"/>), or by default on the
6751 database's
<envar>LC_CTYPE
</envar> locale setting (see
6752 <xref linkend=
"locale"/>). The classification of non-ASCII
6753 characters can vary across platforms even in similarly-named
6754 locales. (But the
<literal>C
</literal> locale never considers any
6755 non-ASCII characters to belong to any of these classes.)
6756 In addition to these standard character
6757 classes,
<productname>PostgreSQL
</productname> defines
6758 the
<literal>word
</literal> character class, which is the same as
6759 <literal>alnum
</literal> plus the underscore (
<literal>_
</literal>)
6761 the
<literal>ascii
</literal> character class, which contains exactly
6762 the
7-bit ASCII set.
6766 There are two special cases of bracket expressions: the bracket
6767 expressions
<literal>[[:
<:]]
</literal> and
6768 <literal>[[:
>:]]
</literal> are constraints,
6769 matching empty strings at the beginning
6770 and end of a word respectively. A word is defined as a sequence
6771 of word characters that is neither preceded nor followed by word
6772 characters. A word character is any character belonging to the
6773 <literal>word
</literal> character class, that is, any letter, digit,
6774 or underscore. This is an extension, compatible with but not
6775 specified by
<acronym>POSIX
</acronym> 1003.2, and should be used with
6776 caution in software intended to be portable to other systems.
6777 The constraint escapes described below are usually preferable; they
6778 are no more standard, but are easier to type.
6782 <sect3 id=
"posix-escape-sequences">
6783 <title>Regular Expression Escapes
</title>
6786 <firstterm>Escapes
</firstterm> are special sequences beginning with
<literal>\
</literal>
6787 followed by an alphanumeric character. Escapes come in several varieties:
6788 character entry, class shorthands, constraint escapes, and back references.
6789 A
<literal>\
</literal> followed by an alphanumeric character but not constituting
6790 a valid escape is illegal in AREs.
6791 In EREs, there are no escapes: outside a bracket expression,
6792 a
<literal>\
</literal> followed by an alphanumeric character merely stands for
6793 that character as an ordinary character, and inside a bracket expression,
6794 <literal>\
</literal> is an ordinary character.
6795 (The latter is the one actual incompatibility between EREs and AREs.)
6799 <firstterm>Character-entry escapes
</firstterm> exist to make it easier to specify
6800 non-printing and other inconvenient characters in REs. They are
6801 shown in
<xref linkend=
"posix-character-entry-escapes-table"/>.
6805 <firstterm>Class-shorthand escapes
</firstterm> provide shorthands for certain
6806 commonly-used character classes. They are
6807 shown in
<xref linkend=
"posix-class-shorthand-escapes-table"/>.
6811 A
<firstterm>constraint escape
</firstterm> is a constraint,
6812 matching the empty string if specific conditions are met,
6813 written as an escape. They are
6814 shown in
<xref linkend=
"posix-constraint-escapes-table"/>.
6818 A
<firstterm>back reference
</firstterm> (
<literal>\
</literal><replaceable>n
</replaceable>) matches the
6819 same string matched by the previous parenthesized subexpression specified
6820 by the number
<replaceable>n
</replaceable>
6821 (see
<xref linkend=
"posix-constraint-backref-table"/>). For example,
6822 <literal>([bc])\
1</literal> matches
<literal>bb
</literal> or
<literal>cc
</literal>
6823 but not
<literal>bc
</literal> or
<literal>cb
</literal>.
6824 The subexpression must entirely precede the back reference in the RE.
6825 Subexpressions are numbered in the order of their leading parentheses.
6826 Non-capturing parentheses do not define subexpressions.
6827 The back reference considers only the string characters matched by the
6828 referenced subexpression, not any constraints contained in it. For
6829 example,
<literal>(^\d)\
1</literal> will match
<literal>22</literal>.
6832 <table id=
"posix-character-entry-escapes-table">
6833 <title>Regular Expression Character-Entry Escapes
</title>
6838 <entry>Escape
</entry>
6839 <entry>Description
</entry>
6845 <entry> <literal>\a
</literal> </entry>
6846 <entry> alert (bell) character, as in C
</entry>
6850 <entry> <literal>\b
</literal> </entry>
6851 <entry> backspace, as in C
</entry>
6855 <entry> <literal>\B
</literal> </entry>
6856 <entry> synonym for backslash (
<literal>\
</literal>) to help reduce the need for backslash
6861 <entry> <literal>\c
</literal><replaceable>X
</replaceable> </entry>
6862 <entry> (where
<replaceable>X
</replaceable> is any character) the character whose
6863 low-order
5 bits are the same as those of
6864 <replaceable>X
</replaceable>, and whose other bits are all zero
</entry>
6868 <entry> <literal>\e
</literal> </entry>
6869 <entry> the character whose collating-sequence name
6870 is
<literal>ESC
</literal>,
6871 or failing that, the character with octal value
<literal>033</literal> </entry>
6875 <entry> <literal>\f
</literal> </entry>
6876 <entry> form feed, as in C
</entry>
6880 <entry> <literal>\n
</literal> </entry>
6881 <entry> newline, as in C
</entry>
6885 <entry> <literal>\r
</literal> </entry>
6886 <entry> carriage return, as in C
</entry>
6890 <entry> <literal>\t
</literal> </entry>
6891 <entry> horizontal tab, as in C
</entry>
6895 <entry> <literal>\u
</literal><replaceable>wxyz
</replaceable> </entry>
6896 <entry> (where
<replaceable>wxyz
</replaceable> is exactly four hexadecimal digits)
6897 the character whose hexadecimal value is
6898 <literal>0x
</literal><replaceable>wxyz
</replaceable>
6903 <entry> <literal>\U
</literal><replaceable>stuvwxyz
</replaceable> </entry>
6904 <entry> (where
<replaceable>stuvwxyz
</replaceable> is exactly eight hexadecimal
6906 the character whose hexadecimal value is
6907 <literal>0x
</literal><replaceable>stuvwxyz
</replaceable>
6912 <entry> <literal>\v
</literal> </entry>
6913 <entry> vertical tab, as in C
</entry>
6917 <entry> <literal>\x
</literal><replaceable>hhh
</replaceable> </entry>
6918 <entry> (where
<replaceable>hhh
</replaceable> is any sequence of hexadecimal
6920 the character whose hexadecimal value is
6921 <literal>0x
</literal><replaceable>hhh
</replaceable>
6922 (a single character no matter how many hexadecimal digits are used)
6927 <entry> <literal>\
0</literal> </entry>
6928 <entry> the character whose value is
<literal>0</literal> (the null byte)
</entry>
6932 <entry> <literal>\
</literal><replaceable>xy
</replaceable> </entry>
6933 <entry> (where
<replaceable>xy
</replaceable> is exactly two octal digits,
6934 and is not a
<firstterm>back reference
</firstterm>)
6935 the character whose octal value is
6936 <literal>0</literal><replaceable>xy
</replaceable> </entry>
6940 <entry> <literal>\
</literal><replaceable>xyz
</replaceable> </entry>
6941 <entry> (where
<replaceable>xyz
</replaceable> is exactly three octal digits,
6942 and is not a
<firstterm>back reference
</firstterm>)
6943 the character whose octal value is
6944 <literal>0</literal><replaceable>xyz
</replaceable> </entry>
6951 Hexadecimal digits are
<literal>0</literal>-
<literal>9</literal>,
6952 <literal>a
</literal>-
<literal>f
</literal>, and
<literal>A
</literal>-
<literal>F
</literal>.
6953 Octal digits are
<literal>0</literal>-
<literal>7</literal>.
6957 Numeric character-entry escapes specifying values outside the ASCII range
6958 (
0–127) have meanings dependent on the database encoding. When the
6959 encoding is UTF-
8, escape values are equivalent to Unicode code points,
6960 for example
<literal>\u1234
</literal> means the character
<literal>U+
1234</literal>.
6961 For other multibyte encodings, character-entry escapes usually just
6962 specify the concatenation of the byte values for the character. If the
6963 escape value does not correspond to any legal character in the database
6964 encoding, no error will be raised, but it will never match any data.
6968 The character-entry escapes are always taken as ordinary characters.
6969 For example,
<literal>\
135</literal> is
<literal>]
</literal> in ASCII, but
6970 <literal>\
135</literal> does not terminate a bracket expression.
6973 <table id=
"posix-class-shorthand-escapes-table">
6974 <title>Regular Expression Class-Shorthand Escapes
</title>
6979 <entry>Escape
</entry>
6980 <entry>Description
</entry>
6986 <entry> <literal>\d
</literal> </entry>
6987 <entry> matches any digit, like
6988 <literal>[[:digit:]]
</literal> </entry>
6992 <entry> <literal>\s
</literal> </entry>
6993 <entry> matches any whitespace character, like
6994 <literal>[[:space:]]
</literal> </entry>
6998 <entry> <literal>\w
</literal> </entry>
6999 <entry> matches any word character, like
7000 <literal>[[:word:]]
</literal> </entry>
7004 <entry> <literal>\D
</literal> </entry>
7005 <entry> matches any non-digit, like
7006 <literal>[^[:digit:]]
</literal> </entry>
7010 <entry> <literal>\S
</literal> </entry>
7011 <entry> matches any non-whitespace character, like
7012 <literal>[^[:space:]]
</literal> </entry>
7016 <entry> <literal>\W
</literal> </entry>
7017 <entry> matches any non-word character, like
7018 <literal>[^[:word:]]
</literal> </entry>
7025 The class-shorthand escapes also work within bracket expressions,
7026 although the definitions shown above are not quite syntactically
7027 valid in that context.
7028 For example,
<literal>[a-c\d]
</literal> is equivalent to
7029 <literal>[a-c[:digit:]]
</literal>.
7032 <table id=
"posix-constraint-escapes-table">
7033 <title>Regular Expression Constraint Escapes
</title>
7038 <entry>Escape
</entry>
7039 <entry>Description
</entry>
7045 <entry> <literal>\A
</literal> </entry>
7046 <entry> matches only at the beginning of the string
7047 (see
<xref linkend=
"posix-matching-rules"/> for how this differs from
7048 <literal>^
</literal>)
</entry>
7052 <entry> <literal>\m
</literal> </entry>
7053 <entry> matches only at the beginning of a word
</entry>
7057 <entry> <literal>\M
</literal> </entry>
7058 <entry> matches only at the end of a word
</entry>
7062 <entry> <literal>\y
</literal> </entry>
7063 <entry> matches only at the beginning or end of a word
</entry>
7067 <entry> <literal>\Y
</literal> </entry>
7068 <entry> matches only at a point that is not the beginning or end of a
7073 <entry> <literal>\Z
</literal> </entry>
7074 <entry> matches only at the end of the string
7075 (see
<xref linkend=
"posix-matching-rules"/> for how this differs from
7076 <literal>$
</literal>)
</entry>
7083 A word is defined as in the specification of
7084 <literal>[[:
<:]]
</literal> and
<literal>[[:
>:]]
</literal> above.
7085 Constraint escapes are illegal within bracket expressions.
7088 <table id=
"posix-constraint-backref-table">
7089 <title>Regular Expression Back References
</title>
7094 <entry>Escape
</entry>
7095 <entry>Description
</entry>
7101 <entry> <literal>\
</literal><replaceable>m
</replaceable> </entry>
7102 <entry> (where
<replaceable>m
</replaceable> is a nonzero digit)
7103 a back reference to the
<replaceable>m
</replaceable>'th subexpression
</entry>
7107 <entry> <literal>\
</literal><replaceable>mnn
</replaceable> </entry>
7108 <entry> (where
<replaceable>m
</replaceable> is a nonzero digit, and
7109 <replaceable>nn
</replaceable> is some more digits, and the decimal value
7110 <replaceable>mnn
</replaceable> is not greater than the number of closing capturing
7111 parentheses seen so far)
7112 a back reference to the
<replaceable>mnn
</replaceable>'th subexpression
</entry>
7120 There is an inherent ambiguity between octal character-entry
7121 escapes and back references, which is resolved by the following heuristics,
7123 A leading zero always indicates an octal escape.
7124 A single non-zero digit, not followed by another digit,
7125 is always taken as a back reference.
7126 A multi-digit sequence not starting with a zero is taken as a back
7127 reference if it comes after a suitable subexpression
7128 (i.e., the number is in the legal range for a back reference),
7129 and otherwise is taken as octal.
7134 <sect3 id=
"posix-metasyntax">
7135 <title>Regular Expression Metasyntax
</title>
7138 In addition to the main syntax described above, there are some special
7139 forms and miscellaneous syntactic facilities available.
7143 An RE can begin with one of two special
<firstterm>director
</firstterm> prefixes.
7144 If an RE begins with
<literal>***:
</literal>,
7145 the rest of the RE is taken as an ARE. (This normally has no effect in
7146 <productname>PostgreSQL
</productname>, since REs are assumed to be AREs;
7147 but it does have an effect if ERE or BRE mode had been specified by
7148 the
<replaceable>flags
</replaceable> parameter to a regex function.)
7149 If an RE begins with
<literal>***=
</literal>,
7150 the rest of the RE is taken to be a literal string,
7151 with all characters considered ordinary characters.
7155 An ARE can begin with
<firstterm>embedded options
</firstterm>:
7156 a sequence
<literal>(?
</literal><replaceable>xyz
</replaceable><literal>)
</literal>
7157 (where
<replaceable>xyz
</replaceable> is one or more alphabetic characters)
7158 specifies options affecting the rest of the RE.
7159 These options override any previously determined options
—
7160 in particular, they can override the case-sensitivity behavior implied by
7161 a regex operator, or the
<replaceable>flags
</replaceable> parameter to a regex
7163 The available option letters are
7164 shown in
<xref linkend=
"posix-embedded-options-table"/>.
7165 Note that these same option letters are used in the
<replaceable>flags
</replaceable>
7166 parameters of regex functions.
7169 <table id=
"posix-embedded-options-table">
7170 <title>ARE Embedded-Option Letters
</title>
7175 <entry>Option
</entry>
7176 <entry>Description
</entry>
7182 <entry> <literal>b
</literal> </entry>
7183 <entry> rest of RE is a BRE
</entry>
7187 <entry> <literal>c
</literal> </entry>
7188 <entry> case-sensitive matching (overrides operator type)
</entry>
7192 <entry> <literal>e
</literal> </entry>
7193 <entry> rest of RE is an ERE
</entry>
7197 <entry> <literal>i
</literal> </entry>
7198 <entry> case-insensitive matching (see
7199 <xref linkend=
"posix-matching-rules"/>) (overrides operator type)
</entry>
7203 <entry> <literal>m
</literal> </entry>
7204 <entry> historical synonym for
<literal>n
</literal> </entry>
7208 <entry> <literal>n
</literal> </entry>
7209 <entry> newline-sensitive matching (see
7210 <xref linkend=
"posix-matching-rules"/>)
</entry>
7214 <entry> <literal>p
</literal> </entry>
7215 <entry> partial newline-sensitive matching (see
7216 <xref linkend=
"posix-matching-rules"/>)
</entry>
7220 <entry> <literal>q
</literal> </entry>
7221 <entry> rest of RE is a literal (
<quote>quoted
</quote>) string, all ordinary
7226 <entry> <literal>s
</literal> </entry>
7227 <entry> non-newline-sensitive matching (default)
</entry>
7231 <entry> <literal>t
</literal> </entry>
7232 <entry> tight syntax (default; see below)
</entry>
7236 <entry> <literal>w
</literal> </entry>
7237 <entry> inverse partial newline-sensitive (
<quote>weird
</quote>) matching
7238 (see
<xref linkend=
"posix-matching-rules"/>)
</entry>
7242 <entry> <literal>x
</literal> </entry>
7243 <entry> expanded syntax (see below)
</entry>
7250 Embedded options take effect at the
<literal>)
</literal> terminating the sequence.
7251 They can appear only at the start of an ARE (after the
7252 <literal>***:
</literal> director if any).
7256 In addition to the usual (
<firstterm>tight
</firstterm>) RE syntax, in which all
7257 characters are significant, there is an
<firstterm>expanded
</firstterm> syntax,
7258 available by specifying the embedded
<literal>x
</literal> option.
7259 In the expanded syntax,
7260 white-space characters in the RE are ignored, as are
7261 all characters between a
<literal>#
</literal>
7262 and the following newline (or the end of the RE). This
7263 permits paragraphing and commenting a complex RE.
7264 There are three exceptions to that basic rule:
7269 a white-space character or
<literal>#
</literal> preceded by
<literal>\
</literal> is
7275 white space or
<literal>#
</literal> within a bracket expression is retained
7280 white space and comments cannot appear within multi-character symbols,
7281 such as
<literal>(?:
</literal>
7286 For this purpose, white-space characters are blank, tab, newline, and
7287 any character that belongs to the
<replaceable>space
</replaceable> character class.
7291 Finally, in an ARE, outside bracket expressions, the sequence
7292 <literal>(?#
</literal><replaceable>ttt
</replaceable><literal>)
</literal>
7293 (where
<replaceable>ttt
</replaceable> is any text not containing a
<literal>)
</literal>)
7294 is a comment, completely ignored.
7295 Again, this is not allowed between the characters of
7296 multi-character symbols, like
<literal>(?:
</literal>.
7297 Such comments are more a historical artifact than a useful facility,
7298 and their use is deprecated; use the expanded syntax instead.
7302 <emphasis>None
</emphasis> of these metasyntax extensions is available if
7303 an initial
<literal>***=
</literal> director
7304 has specified that the user's input be treated as a literal string
7305 rather than as an RE.
7309 <sect3 id=
"posix-matching-rules">
7310 <title>Regular Expression Matching Rules
</title>
7313 In the event that an RE could match more than one substring of a given
7314 string, the RE matches the one starting earliest in the string.
7315 If the RE could match more than one substring starting at that point,
7316 either the longest possible match or the shortest possible match will
7317 be taken, depending on whether the RE is
<firstterm>greedy
</firstterm> or
7318 <firstterm>non-greedy
</firstterm>.
7322 Whether an RE is greedy or not is determined by the following rules:
7326 Most atoms, and all constraints, have no greediness attribute (because
7327 they cannot match variable amounts of text anyway).
7332 Adding parentheses around an RE does not change its greediness.
7337 A quantified atom with a fixed-repetition quantifier
7338 (
<literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal>
7340 <literal>{
</literal><replaceable>m
</replaceable><literal>}?
</literal>)
7341 has the same greediness (possibly none) as the atom itself.
7346 A quantified atom with other normal quantifiers (including
7347 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal>
7348 with
<replaceable>m
</replaceable> equal to
<replaceable>n
</replaceable>)
7349 is greedy (prefers longest match).
7354 A quantified atom with a non-greedy quantifier (including
7355 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}?
</literal>
7356 with
<replaceable>m
</replaceable> equal to
<replaceable>n
</replaceable>)
7357 is non-greedy (prefers shortest match).
7362 A branch
— that is, an RE that has no top-level
7363 <literal>|
</literal> operator
— has the same greediness as the first
7364 quantified atom in it that has a greediness attribute.
7369 An RE consisting of two or more branches connected by the
7370 <literal>|
</literal> operator is always greedy.
7377 The above rules associate greediness attributes not only with individual
7378 quantified atoms, but with branches and entire REs that contain quantified
7379 atoms. What that means is that the matching is done in such a way that
7380 the branch, or whole RE, matches the longest or shortest possible
7381 substring
<emphasis>as a whole
</emphasis>. Once the length of the entire match
7382 is determined, the part of it that matches any particular subexpression
7383 is determined on the basis of the greediness attribute of that
7384 subexpression, with subexpressions starting earlier in the RE taking
7385 priority over ones starting later.
7389 An example of what this means:
7391 SELECT SUBSTRING('XY1234Z', 'Y*([
0-
9]{
1,
3})');
7392 <lineannotation>Result:
</lineannotation><computeroutput>123</computeroutput>
7393 SELECT SUBSTRING('XY1234Z', 'Y*?([
0-
9]{
1,
3})');
7394 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
7396 In the first case, the RE as a whole is greedy because
<literal>Y*
</literal>
7397 is greedy. It can match beginning at the
<literal>Y
</literal>, and it matches
7398 the longest possible string starting there, i.e.,
<literal>Y123
</literal>.
7399 The output is the parenthesized part of that, or
<literal>123</literal>.
7400 In the second case, the RE as a whole is non-greedy because
<literal>Y*?
</literal>
7401 is non-greedy. It can match beginning at the
<literal>Y
</literal>, and it matches
7402 the shortest possible string starting there, i.e.,
<literal>Y1
</literal>.
7403 The subexpression
<literal>[
0-
9]{
1,
3}
</literal> is greedy but it cannot change
7404 the decision as to the overall match length; so it is forced to match
7405 just
<literal>1</literal>.
7409 In short, when an RE contains both greedy and non-greedy subexpressions,
7410 the total match length is either as long as possible or as short as
7411 possible, according to the attribute assigned to the whole RE. The
7412 attributes assigned to the subexpressions only affect how much of that
7413 match they are allowed to
<quote>eat
</quote> relative to each other.
7417 The quantifiers
<literal>{
1,
1}
</literal> and
<literal>{
1,
1}?
</literal>
7418 can be used to force greediness or non-greediness, respectively,
7419 on a subexpression or a whole RE.
7420 This is useful when you need the whole RE to have a greediness attribute
7421 different from what's deduced from its elements. As an example,
7422 suppose that we are trying to separate a string containing some digits
7423 into the digits and the parts before and after them. We might try to
7426 SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
7427 <lineannotation>Result:
</lineannotation><computeroutput>{abc0123,
4,xyz}
</computeroutput>
7429 That didn't work: the first
<literal>.*
</literal> is greedy so
7430 it
<quote>eats
</quote> as much as it can, leaving the
<literal>\d+
</literal> to
7431 match at the last possible place, the last digit. We might try to fix
7432 that by making it non-greedy:
7434 SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
7435 <lineannotation>Result:
</lineannotation><computeroutput>{abc,
0,
""}
</computeroutput>
7437 That didn't work either, because now the RE as a whole is non-greedy
7438 and so it ends the overall match as soon as possible. We can get what
7439 we want by forcing the RE as a whole to be greedy:
7441 SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){
1,
1}');
7442 <lineannotation>Result:
</lineannotation><computeroutput>{abc,
01234,xyz}
</computeroutput>
7444 Controlling the RE's overall greediness separately from its components'
7445 greediness allows great flexibility in handling variable-length patterns.
7449 When deciding what is a longer or shorter match,
7450 match lengths are measured in characters, not collating elements.
7451 An empty string is considered longer than no match at all.
7453 <literal>bb*
</literal>
7454 matches the three middle characters of
<literal>abbbc
</literal>;
7455 <literal>(week|wee)(night|knights)
</literal>
7456 matches all ten characters of
<literal>weeknights
</literal>;
7457 when
<literal>(.*).*
</literal>
7458 is matched against
<literal>abc
</literal> the parenthesized subexpression
7459 matches all three characters; and when
7460 <literal>(a*)*
</literal> is matched against
<literal>bc
</literal>
7461 both the whole RE and the parenthesized
7462 subexpression match an empty string.
7466 If case-independent matching is specified,
7467 the effect is much as if all case distinctions had vanished from the
7469 When an alphabetic that exists in multiple cases appears as an
7470 ordinary character outside a bracket expression, it is effectively
7471 transformed into a bracket expression containing both cases,
7472 e.g.,
<literal>x
</literal> becomes
<literal>[xX]
</literal>.
7473 When it appears inside a bracket expression, all case counterparts
7474 of it are added to the bracket expression, e.g.,
7475 <literal>[x]
</literal> becomes
<literal>[xX]
</literal>
7476 and
<literal>[^x]
</literal> becomes
<literal>[^xX]
</literal>.
7480 If newline-sensitive matching is specified,
<literal>.
</literal>
7481 and bracket expressions using
<literal>^
</literal>
7482 will never match the newline character
7483 (so that matches will not cross lines unless the RE
7484 explicitly includes a newline)
7485 and
<literal>^
</literal> and
<literal>$
</literal>
7486 will match the empty string after and before a newline
7487 respectively, in addition to matching at beginning and end of string
7489 But the ARE escapes
<literal>\A
</literal> and
<literal>\Z
</literal>
7490 continue to match beginning or end of string
<emphasis>only
</emphasis>.
7491 Also, the character class shorthands
<literal>\D
</literal>
7492 and
<literal>\W
</literal> will match a newline regardless of this mode.
7493 (Before
<productname>PostgreSQL
</productname> 14, they did not match
7494 newlines when in newline-sensitive mode.
7495 Write
<literal>[^[:digit:]]
</literal>
7496 or
<literal>[^[:word:]]
</literal> to get the old behavior.)
7500 If partial newline-sensitive matching is specified,
7501 this affects
<literal>.
</literal> and bracket expressions
7502 as with newline-sensitive matching, but not
<literal>^
</literal>
7503 and
<literal>$
</literal>.
7507 If inverse partial newline-sensitive matching is specified,
7508 this affects
<literal>^
</literal> and
<literal>$
</literal>
7509 as with newline-sensitive matching, but not
<literal>.
</literal>
7510 and bracket expressions.
7511 This isn't very useful but is provided for symmetry.
7515 <sect3 id=
"posix-limits-compatibility">
7516 <title>Limits and Compatibility
</title>
7519 No particular limit is imposed on the length of REs in this
7520 implementation. However,
7521 programs intended to be highly portable should not employ REs longer
7523 as a POSIX-compliant implementation can refuse to accept such REs.
7527 The only feature of AREs that is actually incompatible with
7528 POSIX EREs is that
<literal>\
</literal> does not lose its special
7529 significance inside bracket expressions.
7530 All other ARE features use syntax which is illegal or has
7531 undefined or unspecified effects in POSIX EREs;
7532 the
<literal>***
</literal> syntax of directors likewise is outside the POSIX
7533 syntax for both BREs and EREs.
7537 Many of the ARE extensions are borrowed from Perl, but some have
7538 been changed to clean them up, and a few Perl extensions are not present.
7539 Incompatibilities of note include
<literal>\b
</literal>,
<literal>\B
</literal>,
7540 the lack of special treatment for a trailing newline,
7541 the addition of complemented bracket expressions to the things
7542 affected by newline-sensitive matching,
7543 the restrictions on parentheses and back references in lookahead/lookbehind
7544 constraints, and the longest/shortest-match (rather than first-match)
7549 <sect3 id=
"posix-basic-regexes">
7550 <title>Basic Regular Expressions
</title>
7553 BREs differ from EREs in several respects.
7554 In BREs,
<literal>|
</literal>,
<literal>+
</literal>, and
<literal>?
</literal>
7555 are ordinary characters and there is no equivalent
7556 for their functionality.
7557 The delimiters for bounds are
7558 <literal>\{
</literal> and
<literal>\}
</literal>,
7559 with
<literal>{
</literal> and
<literal>}
</literal>
7560 by themselves ordinary characters.
7561 The parentheses for nested subexpressions are
7562 <literal>\(
</literal> and
<literal>\)
</literal>,
7563 with
<literal>(
</literal> and
<literal>)
</literal> by themselves ordinary characters.
7564 <literal>^
</literal> is an ordinary character except at the beginning of the
7565 RE or the beginning of a parenthesized subexpression,
7566 <literal>$
</literal> is an ordinary character except at the end of the
7567 RE or the end of a parenthesized subexpression,
7568 and
<literal>*
</literal> is an ordinary character if it appears at the beginning
7569 of the RE or the beginning of a parenthesized subexpression
7570 (after a possible leading
<literal>^
</literal>).
7571 Finally, single-digit back references are available, and
7572 <literal>\
<</literal> and
<literal>\
></literal>
7574 <literal>[[:
<:]]
</literal> and
<literal>[[:
>:]]
</literal>
7575 respectively; no other escapes are available in BREs.
7579 <!-- end re_syntax.n man page -->
7581 <sect3 id=
"posix-vs-xquery">
7582 <title>Differences from SQL Standard and XQuery
</title>
7584 <indexterm zone=
"posix-vs-xquery">
7585 <primary>LIKE_REGEX
</primary>
7588 <indexterm zone=
"posix-vs-xquery">
7589 <primary>OCCURRENCES_REGEX
</primary>
7592 <indexterm zone=
"posix-vs-xquery">
7593 <primary>POSITION_REGEX
</primary>
7596 <indexterm zone=
"posix-vs-xquery">
7597 <primary>SUBSTRING_REGEX
</primary>
7600 <indexterm zone=
"posix-vs-xquery">
7601 <primary>TRANSLATE_REGEX
</primary>
7604 <indexterm zone=
"posix-vs-xquery">
7605 <primary>XQuery regular expressions
</primary>
7609 Since SQL:
2008, the SQL standard includes regular expression operators
7610 and functions that performs pattern
7611 matching according to the XQuery regular expression
7614 <listitem><para><literal>LIKE_REGEX
</literal></para></listitem>
7615 <listitem><para><literal>OCCURRENCES_REGEX
</literal></para></listitem>
7616 <listitem><para><literal>POSITION_REGEX
</literal></para></listitem>
7617 <listitem><para><literal>SUBSTRING_REGEX
</literal></para></listitem>
7618 <listitem><para><literal>TRANSLATE_REGEX
</literal></para></listitem>
7620 <productname>PostgreSQL
</productname> does not currently implement these
7621 operators and functions. You can get approximately equivalent
7622 functionality in each case as shown in
<xref
7623 linkend=
"functions-regexp-sql-table"/>. (Various optional clauses on
7624 both sides have been omitted in this table.)
7627 <table id=
"functions-regexp-sql-table">
7628 <title>Regular Expression Functions Equivalencies
</title>
7633 <entry>SQL standard
</entry>
7634 <entry><productname>PostgreSQL
</productname></entry>
7640 <entry><literal><replaceable>string
</replaceable> LIKE_REGEX
<replaceable>pattern
</replaceable></literal></entry>
7641 <entry><literal>regexp_like(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal> or
<literal><replaceable>string
</replaceable> ~
<replaceable>pattern
</replaceable></literal></entry>
7645 <entry><literal>OCCURRENCES_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable>)
</literal></entry>
7646 <entry><literal>regexp_count(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal></entry>
7650 <entry><literal>POSITION_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable>)
</literal></entry>
7651 <entry><literal>regexp_instr(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal></entry>
7655 <entry><literal>SUBSTRING_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable>)
</literal></entry>
7656 <entry><literal>regexp_substr(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal></entry>
7660 <entry><literal>TRANSLATE_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable> WITH
<replaceable>replacement
</replaceable>)
</literal></entry>
7661 <entry><literal>regexp_replace(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>,
<replaceable>replacement
</replaceable>)
</literal></entry>
7668 Regular expression functions similar to those provided by PostgreSQL are
7669 also available in a number of other SQL implementations, whereas the
7670 SQL-standard functions are not as widely implemented. Some of the
7671 details of the regular expression syntax will likely differ in each
7676 The SQL-standard operators and functions use XQuery regular expressions,
7677 which are quite close to the ARE syntax described above.
7678 Notable differences between the existing POSIX-based
7679 regular-expression feature and XQuery regular expressions include:
7684 XQuery character class subtraction is not supported. An example of
7685 this feature is using the following to match only English
7686 consonants:
<literal>[a-z-[aeiou]]
</literal>.
7691 XQuery character class shorthands
<literal>\c
</literal>,
7692 <literal>\C
</literal>,
<literal>\i
</literal>,
7693 and
<literal>\I
</literal> are not supported.
7698 XQuery character class elements
7699 using
<literal>\p{UnicodeProperty}
</literal> or the
7700 inverse
<literal>\P{UnicodeProperty}
</literal> are not supported.
7705 POSIX interprets character classes such as
<literal>\w
</literal>
7706 (see
<xref linkend=
"posix-class-shorthand-escapes-table"/>)
7707 according to the prevailing locale (which you can control by
7708 attaching a
<literal>COLLATE
</literal> clause to the operator or
7709 function). XQuery specifies these classes by reference to Unicode
7710 character properties, so equivalent behavior is obtained only with
7711 a locale that follows the Unicode rules.
7716 The SQL standard (not XQuery itself) attempts to cater for more
7717 variants of
<quote>newline
</quote> than POSIX does. The
7718 newline-sensitive matching options described above consider only
7719 ASCII NL (
<literal>\n
</literal>) to be a newline, but SQL would have
7720 us treat CR (
<literal>\r
</literal>), CRLF (
<literal>\r\n
</literal>)
7721 (a Windows-style newline), and some Unicode-only characters like
7722 LINE SEPARATOR (U+
2028) as newlines as well.
7723 Notably,
<literal>.
</literal> and
<literal>\s
</literal> should
7724 count
<literal>\r\n
</literal> as one character not two according to
7730 Of the character-entry escapes described in
7731 <xref linkend=
"posix-character-entry-escapes-table"/>,
7732 XQuery supports only
<literal>\n
</literal>,
<literal>\r
</literal>,
7733 and
<literal>\t
</literal>.
7738 XQuery does not support
7739 the
<literal>[:
<replaceable>name
</replaceable>:]
</literal> syntax
7740 for character classes within bracket expressions.
7745 XQuery does not have lookahead or lookbehind constraints,
7746 nor any of the constraint escapes described in
7747 <xref linkend=
"posix-constraint-escapes-table"/>.
7752 The metasyntax forms described in
<xref linkend=
"posix-metasyntax"/>
7753 do not exist in XQuery.
7758 The regular expression flag letters defined by XQuery are
7759 related to but not the same as the option letters for POSIX
7760 (
<xref linkend=
"posix-embedded-options-table"/>). While the
7761 <literal>i
</literal> and
<literal>q
</literal> options behave the
7762 same, others do not:
7766 XQuery's
<literal>s
</literal> (allow dot to match newline)
7767 and
<literal>m
</literal> (allow
<literal>^
</literal>
7768 and
<literal>$
</literal> to match at newlines) flags provide
7769 access to the same behaviors as
7770 POSIX's
<literal>n
</literal>,
<literal>p
</literal>
7771 and
<literal>w
</literal> flags, but they
7772 do
<emphasis>not
</emphasis> match the behavior of
7773 POSIX's
<literal>s
</literal> and
<literal>m
</literal> flags.
7774 Note in particular that dot-matches-newline is the default
7775 behavior in POSIX but not XQuery.
7780 XQuery's
<literal>x
</literal> (ignore whitespace in pattern) flag
7781 is noticeably different from POSIX's expanded-mode flag.
7782 POSIX's
<literal>x
</literal> flag also
7783 allows
<literal>#
</literal> to begin a comment in the pattern,
7784 and POSIX will not ignore a whitespace character after a
7799 <sect1 id=
"functions-formatting">
7800 <title>Data Type Formatting Functions
</title>
7803 <primary>formatting
</primary>
7807 The
<productname>PostgreSQL
</productname> formatting functions
7808 provide a powerful set of tools for converting various data types
7809 (date/time, integer, floating point, numeric) to formatted strings
7810 and for converting from formatted strings to specific data types.
7811 <xref linkend=
"functions-formatting-table"/> lists them.
7812 These functions all follow a common calling convention: the first
7813 argument is the value to be formatted and the second argument is a
7814 template that defines the output or input format.
7817 <table id=
"functions-formatting-table">
7818 <title>Formatting Functions
</title>
7822 <entry role=
"func_table_entry"><para role=
"func_signature">
7836 <entry role=
"func_table_entry"><para role=
"func_signature">
7838 <primary>to_char
</primary>
7840 <function>to_char
</function> (
<type>timestamp
</type>,
<type>text
</type> )
7841 <returnvalue>text
</returnvalue>
7843 <para role=
"func_signature">
7844 <function>to_char
</function> (
<type>timestamp with time zone
</type>,
<type>text
</type> )
7845 <returnvalue>text
</returnvalue>
7848 Converts time stamp to string according to the given format.
7851 <literal>to_char(timestamp '
2002-
04-
20 17:
31:
12.66', 'HH12:MI:SS')
</literal>
7852 <returnvalue>05:
31:
12</returnvalue>
7857 <entry role=
"func_table_entry"><para role=
"func_signature">
7858 <function>to_char
</function> (
<type>interval
</type>,
<type>text
</type> )
7859 <returnvalue>text
</returnvalue>
7862 Converts interval to string according to the given format.
7865 <literal>to_char(interval '
15h
2m
12s', 'HH24:MI:SS')
</literal>
7866 <returnvalue>15:
02:
12</returnvalue>
7871 <entry role=
"func_table_entry"><para role=
"func_signature">
7872 <function>to_char
</function> (
<replaceable>numeric_type
</replaceable>,
<type>text
</type> )
7873 <returnvalue>text
</returnvalue>
7876 Converts number to string according to the given format; available
7877 for
<type>integer
</type>,
<type>bigint
</type>,
<type>numeric
</type>,
7878 <type>real
</type>,
<type>double precision
</type>.
7881 <literal>to_char(
125, '
999')
</literal>
7882 <returnvalue>125</returnvalue>
7885 <literal>to_char(
125.8::real, '
999D9')
</literal>
7886 <returnvalue>125.8</returnvalue>
7889 <literal>to_char(-
125.8, '
999D99S')
</literal>
7890 <returnvalue>125.80-
</returnvalue>
7895 <entry role=
"func_table_entry"><para role=
"func_signature">
7897 <primary>to_date
</primary>
7899 <function>to_date
</function> (
<type>text
</type>,
<type>text
</type> )
7900 <returnvalue>date
</returnvalue>
7903 Converts string to date according to the given format.
7906 <literal>to_date('
05 Dec
2000', 'DD Mon YYYY')
</literal>
7907 <returnvalue>2000-
12-
05</returnvalue>
7912 <entry role=
"func_table_entry"><para role=
"func_signature">
7914 <primary>to_number
</primary>
7916 <function>to_number
</function> (
<type>text
</type>,
<type>text
</type> )
7917 <returnvalue>numeric
</returnvalue>
7920 Converts string to numeric according to the given format.
7923 <literal>to_number('
12,
454.8-', '
99G999D9S')
</literal>
7924 <returnvalue>-
12454.8</returnvalue>
7929 <entry role=
"func_table_entry"><para role=
"func_signature">
7931 <primary>to_timestamp
</primary>
7933 <function>to_timestamp
</function> (
<type>text
</type>,
<type>text
</type> )
7934 <returnvalue>timestamp with time zone
</returnvalue>
7937 Converts string to time stamp according to the given format.
7938 (See also
<function>to_timestamp(double precision)
</function> in
7939 <xref linkend=
"functions-datetime-table"/>.)
7942 <literal>to_timestamp('
05 Dec
2000', 'DD Mon YYYY')
</literal>
7943 <returnvalue>2000-
12-
05 00:
00:
00-
05</returnvalue>
7952 <function>to_timestamp
</function> and
<function>to_date
</function>
7953 exist to handle input formats that cannot be converted by
7954 simple casting. For most standard date/time formats, simply casting the
7955 source string to the required data type works, and is much easier.
7956 Similarly,
<function>to_number
</function> is unnecessary for standard numeric
7962 In a
<function>to_char
</function> output template string, there are certain
7963 patterns that are recognized and replaced with appropriately-formatted
7964 data based on the given value. Any text that is not a template pattern is
7965 simply copied verbatim. Similarly, in an input template string (for the
7966 other functions), template patterns identify the values to be supplied by
7967 the input data string. If there are characters in the template string
7968 that are not template patterns, the corresponding characters in the input
7969 data string are simply skipped over (whether or not they are equal to the
7970 template string characters).
7974 <xref linkend=
"functions-formatting-datetime-table"/> shows the
7975 template patterns available for formatting date and time values.
7978 <table id=
"functions-formatting-datetime-table">
7979 <title>Template Patterns for Date/Time Formatting
</title>
7983 <entry>Pattern
</entry>
7984 <entry>Description
</entry>
7989 <entry><literal>HH
</literal></entry>
7990 <entry>hour of day (
01–12)
</entry>
7993 <entry><literal>HH12
</literal></entry>
7994 <entry>hour of day (
01–12)
</entry>
7997 <entry><literal>HH24
</literal></entry>
7998 <entry>hour of day (
00–23)
</entry>
8001 <entry><literal>MI
</literal></entry>
8002 <entry>minute (
00–59)
</entry>
8005 <entry><literal>SS
</literal></entry>
8006 <entry>second (
00–59)
</entry>
8009 <entry><literal>MS
</literal></entry>
8010 <entry>millisecond (
000–999)
</entry>
8013 <entry><literal>US
</literal></entry>
8014 <entry>microsecond (
000000–999999)
</entry>
8017 <entry><literal>FF1
</literal></entry>
8018 <entry>tenth of second (
0–9)
</entry>
8021 <entry><literal>FF2
</literal></entry>
8022 <entry>hundredth of second (
00–99)
</entry>
8025 <entry><literal>FF3
</literal></entry>
8026 <entry>millisecond (
000–999)
</entry>
8029 <entry><literal>FF4
</literal></entry>
8030 <entry>tenth of a millisecond (
0000–9999)
</entry>
8033 <entry><literal>FF5
</literal></entry>
8034 <entry>hundredth of a millisecond (
00000–99999)
</entry>
8037 <entry><literal>FF6
</literal></entry>
8038 <entry>microsecond (
000000–999999)
</entry>
8041 <entry><literal>SSSS
</literal>,
<literal>SSSSS
</literal></entry>
8042 <entry>seconds past midnight (
0–86399)
</entry>
8045 <entry><literal>AM
</literal>,
<literal>am
</literal>,
8046 <literal>PM
</literal> or
<literal>pm
</literal></entry>
8047 <entry>meridiem indicator (without periods)
</entry>
8050 <entry><literal>A.M.
</literal>,
<literal>a.m.
</literal>,
8051 <literal>P.M.
</literal> or
<literal>p.m.
</literal></entry>
8052 <entry>meridiem indicator (with periods)
</entry>
8055 <entry><literal>Y,YYY
</literal></entry>
8056 <entry>year (
4 or more digits) with comma
</entry>
8059 <entry><literal>YYYY
</literal></entry>
8060 <entry>year (
4 or more digits)
</entry>
8063 <entry><literal>YYY
</literal></entry>
8064 <entry>last
3 digits of year
</entry>
8067 <entry><literal>YY
</literal></entry>
8068 <entry>last
2 digits of year
</entry>
8071 <entry><literal>Y
</literal></entry>
8072 <entry>last digit of year
</entry>
8075 <entry><literal>IYYY
</literal></entry>
8076 <entry>ISO
8601 week-numbering year (
4 or more digits)
</entry>
8079 <entry><literal>IYY
</literal></entry>
8080 <entry>last
3 digits of ISO
8601 week-numbering year
</entry>
8083 <entry><literal>IY
</literal></entry>
8084 <entry>last
2 digits of ISO
8601 week-numbering year
</entry>
8087 <entry><literal>I
</literal></entry>
8088 <entry>last digit of ISO
8601 week-numbering year
</entry>
8091 <entry><literal>BC
</literal>,
<literal>bc
</literal>,
8092 <literal>AD
</literal> or
<literal>ad
</literal></entry>
8093 <entry>era indicator (without periods)
</entry>
8096 <entry><literal>B.C.
</literal>,
<literal>b.c.
</literal>,
8097 <literal>A.D.
</literal> or
<literal>a.d.
</literal></entry>
8098 <entry>era indicator (with periods)
</entry>
8101 <entry><literal>MONTH
</literal></entry>
8102 <entry>full upper case month name (blank-padded to
9 chars)
</entry>
8105 <entry><literal>Month
</literal></entry>
8106 <entry>full capitalized month name (blank-padded to
9 chars)
</entry>
8109 <entry><literal>month
</literal></entry>
8110 <entry>full lower case month name (blank-padded to
9 chars)
</entry>
8113 <entry><literal>MON
</literal></entry>
8114 <entry>abbreviated upper case month name (
3 chars in English, localized lengths vary)
</entry>
8117 <entry><literal>Mon
</literal></entry>
8118 <entry>abbreviated capitalized month name (
3 chars in English, localized lengths vary)
</entry>
8121 <entry><literal>mon
</literal></entry>
8122 <entry>abbreviated lower case month name (
3 chars in English, localized lengths vary)
</entry>
8125 <entry><literal>MM
</literal></entry>
8126 <entry>month number (
01–12)
</entry>
8129 <entry><literal>DAY
</literal></entry>
8130 <entry>full upper case day name (blank-padded to
9 chars)
</entry>
8133 <entry><literal>Day
</literal></entry>
8134 <entry>full capitalized day name (blank-padded to
9 chars)
</entry>
8137 <entry><literal>day
</literal></entry>
8138 <entry>full lower case day name (blank-padded to
9 chars)
</entry>
8141 <entry><literal>DY
</literal></entry>
8142 <entry>abbreviated upper case day name (
3 chars in English, localized lengths vary)
</entry>
8145 <entry><literal>Dy
</literal></entry>
8146 <entry>abbreviated capitalized day name (
3 chars in English, localized lengths vary)
</entry>
8149 <entry><literal>dy
</literal></entry>
8150 <entry>abbreviated lower case day name (
3 chars in English, localized lengths vary)
</entry>
8153 <entry><literal>DDD
</literal></entry>
8154 <entry>day of year (
001–366)
</entry>
8157 <entry><literal>IDDD
</literal></entry>
8158 <entry>day of ISO
8601 week-numbering year (
001–371; day
1 of the year is Monday of the first ISO week)
</entry>
8161 <entry><literal>DD
</literal></entry>
8162 <entry>day of month (
01–31)
</entry>
8165 <entry><literal>D
</literal></entry>
8166 <entry>day of the week, Sunday (
<literal>1</literal>) to Saturday (
<literal>7</literal>)
</entry>
8169 <entry><literal>ID
</literal></entry>
8170 <entry>ISO
8601 day of the week, Monday (
<literal>1</literal>) to Sunday (
<literal>7</literal>)
</entry>
8173 <entry><literal>W
</literal></entry>
8174 <entry>week of month (
1–5) (the first week starts on the first day of the month)
</entry>
8177 <entry><literal>WW
</literal></entry>
8178 <entry>week number of year (
1–53) (the first week starts on the first day of the year)
</entry>
8181 <entry><literal>IW
</literal></entry>
8182 <entry>week number of ISO
8601 week-numbering year (
01–53; the first Thursday of the year is in week
1)
</entry>
8185 <entry><literal>CC
</literal></entry>
8186 <entry>century (
2 digits) (the twenty-first century starts on
2001-
01-
01)
</entry>
8189 <entry><literal>J
</literal></entry>
8190 <entry>Julian Date (integer days since November
24,
4714 BC at local
8191 midnight; see
<xref linkend=
"datetime-julian-dates"/>)
</entry>
8194 <entry><literal>Q
</literal></entry>
8195 <entry>quarter
</entry>
8198 <entry><literal>RM
</literal></entry>
8199 <entry>month in upper case Roman numerals (I
–XII; I=January)
</entry>
8202 <entry><literal>rm
</literal></entry>
8203 <entry>month in lower case Roman numerals (i
–xii; i=January)
</entry>
8206 <entry><literal>TZ
</literal></entry>
8207 <entry>upper case time-zone abbreviation
</entry>
8210 <entry><literal>tz
</literal></entry>
8211 <entry>lower case time-zone abbreviation
</entry>
8214 <entry><literal>TZH
</literal></entry>
8215 <entry>time-zone hours
</entry>
8218 <entry><literal>TZM
</literal></entry>
8219 <entry>time-zone minutes
</entry>
8222 <entry><literal>OF
</literal></entry>
8223 <entry>time-zone offset from UTC (
<replaceable>HH
</replaceable>
8224 or
<replaceable>HH
</replaceable><literal>:
</literal><replaceable>MM
</replaceable>)
</entry>
8231 Modifiers can be applied to any template pattern to alter its
8232 behavior. For example,
<literal>FMMonth
</literal>
8233 is the
<literal>Month
</literal> pattern with the
8234 <literal>FM
</literal> modifier.
8235 <xref linkend=
"functions-formatting-datetimemod-table"/> shows the
8236 modifier patterns for date/time formatting.
8239 <table id=
"functions-formatting-datetimemod-table">
8240 <title>Template Pattern Modifiers for Date/Time Formatting
</title>
8244 <entry>Modifier
</entry>
8245 <entry>Description
</entry>
8246 <entry>Example
</entry>
8251 <entry><literal>FM
</literal> prefix
</entry>
8252 <entry>fill mode (suppress leading zeroes and padding blanks)
</entry>
8253 <entry><literal>FMMonth
</literal></entry>
8256 <entry><literal>TH
</literal> suffix
</entry>
8257 <entry>upper case ordinal number suffix
</entry>
8258 <entry><literal>DDTH
</literal>, e.g.,
<literal>12TH
</literal></entry>
8261 <entry><literal>th
</literal> suffix
</entry>
8262 <entry>lower case ordinal number suffix
</entry>
8263 <entry><literal>DDth
</literal>, e.g.,
<literal>12th
</literal></entry>
8266 <entry><literal>FX
</literal> prefix
</entry>
8267 <entry>fixed format global option (see usage notes)
</entry>
8268 <entry><literal>FX
Month
DD
Day
</literal></entry>
8271 <entry><literal>TM
</literal> prefix
</entry>
8272 <entry>translation mode (use localized day and month names based on
8273 <xref linkend=
"guc-lc-time"/>)
</entry>
8274 <entry><literal>TMMonth
</literal></entry>
8277 <entry><literal>SP
</literal> suffix
</entry>
8278 <entry>spell mode (not implemented)
</entry>
8279 <entry><literal>DDSP
</literal></entry>
8286 Usage notes for date/time formatting:
8291 <literal>FM
</literal> suppresses leading zeroes and trailing blanks
8292 that would otherwise be added to make the output of a pattern be
8293 fixed-width. In
<productname>PostgreSQL
</productname>,
8294 <literal>FM
</literal> modifies only the next specification, while in
8295 Oracle
<literal>FM
</literal> affects all subsequent
8296 specifications, and repeated
<literal>FM
</literal> modifiers
8297 toggle fill mode on and off.
8303 <literal>TM
</literal> suppresses trailing blanks whether or
8304 not
<literal>FM
</literal> is specified.
8310 <function>to_timestamp
</function> and
<function>to_date
</function>
8311 ignore letter case in the input; so for
8312 example
<literal>MON
</literal>,
<literal>Mon
</literal>,
8313 and
<literal>mon
</literal> all accept the same strings. When using
8314 the
<literal>TM
</literal> modifier, case-folding is done according to
8315 the rules of the function's input collation (see
8316 <xref linkend=
"collation"/>).
8322 <function>to_timestamp
</function> and
<function>to_date
</function>
8323 skip multiple blank spaces at the beginning of the input string and
8324 around date and time values unless the
<literal>FX
</literal> option is used. For example,
8325 <literal>to_timestamp('
2000 JUN', 'YYYY MON')
</literal> and
8326 <literal>to_timestamp('
2000 - JUN', 'YYYY-MON')
</literal> work, but
8327 <literal>to_timestamp('
2000 JUN', 'FXYYYY MON')
</literal> returns an error
8328 because
<function>to_timestamp
</function> expects only a single space.
8329 <literal>FX
</literal> must be specified as the first item in
8336 A separator (a space or non-letter/non-digit character) in the template string of
8337 <function>to_timestamp
</function> and
<function>to_date
</function>
8338 matches any single separator in the input string or is skipped,
8339 unless the
<literal>FX
</literal> option is used.
8340 For example,
<literal>to_timestamp('
2000JUN', 'YYYY///MON')
</literal> and
8341 <literal>to_timestamp('
2000/JUN', 'YYYY MON')
</literal> work, but
8342 <literal>to_timestamp('
2000//JUN', 'YYYY/MON')
</literal>
8343 returns an error because the number of separators in the input string
8344 exceeds the number of separators in the template.
8347 If
<literal>FX
</literal> is specified, a separator in the template string
8348 matches exactly one character in the input string. But note that the
8349 input string character is not required to be the same as the separator from the template string.
8350 For example,
<literal>to_timestamp('
2000/JUN', 'FXYYYY MON')
</literal>
8351 works, but
<literal>to_timestamp('
2000/JUN', 'FXYYYY
MON')
</literal>
8352 returns an error because the second space in the template string consumes
8353 the letter
<literal>J
</literal> from the input string.
8359 A
<literal>TZH
</literal> template pattern can match a signed number.
8360 Without the
<literal>FX
</literal> option, minus signs may be ambiguous,
8361 and could be interpreted as a separator.
8362 This ambiguity is resolved as follows: If the number of separators before
8363 <literal>TZH
</literal> in the template string is less than the number of
8364 separators before the minus sign in the input string, the minus sign
8365 is interpreted as part of
<literal>TZH
</literal>.
8366 Otherwise, the minus sign is considered to be a separator between values.
8367 For example,
<literal>to_timestamp('
2000 -
10', 'YYYY TZH')
</literal> matches
8368 <literal>-
10</literal> to
<literal>TZH
</literal>, but
8369 <literal>to_timestamp('
2000 -
10', 'YYYY
TZH')
</literal>
8370 matches
<literal>10</literal> to
<literal>TZH
</literal>.
8376 Ordinary text is allowed in
<function>to_char
</function>
8377 templates and will be output literally. You can put a substring
8378 in double quotes to force it to be interpreted as literal text
8379 even if it contains template patterns. For example, in
8380 <literal>'
"Hello Year "YYYY'
</literal>, the
<literal>YYYY
</literal>
8381 will be replaced by the year data, but the single
<literal>Y
</literal> in
<literal>Year
</literal>
8383 In
<function>to_date
</function>,
<function>to_number
</function>,
8384 and
<function>to_timestamp
</function>, literal text and double-quoted
8385 strings result in skipping the number of characters contained in the
8386 string; for example
<literal>"XX"</literal> skips two input characters
8387 (whether or not they are
<literal>XX
</literal>).
8391 Prior to
<productname>PostgreSQL
</productname> 12, it was possible to
8392 skip arbitrary text in the input string using non-letter or non-digit
8393 characters. For example,
8394 <literal>to_timestamp('
2000y6m1d', 'yyyy-MM-DD')
</literal> used to
8395 work. Now you can only use letter characters for this purpose. For example,
8396 <literal>to_timestamp('
2000y6m1d', 'yyyytMMtDDt')
</literal> and
8397 <literal>to_timestamp('
2000y6m1d', 'yyyy
"y"MM
"m"DD
"d"')
</literal>
8398 skip
<literal>y
</literal>,
<literal>m
</literal>, and
8399 <literal>d
</literal>.
8406 If you want to have a double quote in the output you must
8407 precede it with a backslash, for example
<literal>'\
"YYYY
8408 Month\"'
</literal>.
<!-- "" font-lock sanity :-) -->
8409 Backslashes are not otherwise special outside of double-quoted
8410 strings. Within a double-quoted string, a backslash causes the
8411 next character to be taken literally, whatever it is (but this
8412 has no special effect unless the next character is a double quote
8413 or another backslash).
8419 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8420 if the year format specification is less than four digits, e.g.,
8421 <literal>YYY
</literal>, and the supplied year is less than four digits,
8422 the year will be adjusted to be nearest to the year
2020, e.g.,
8423 <literal>95</literal> becomes
1995.
8429 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8430 negative years are treated as signifying BC. If you write both a
8431 negative year and an explicit
<literal>BC
</literal> field, you get AD
8432 again. An input of year zero is treated as
1 BC.
8438 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8439 the
<literal>YYYY
</literal> conversion has a restriction when
8440 processing years with more than
4 digits. You must
8441 use some non-digit character or template after
<literal>YYYY
</literal>,
8442 otherwise the year is always interpreted as
4 digits. For example
8443 (with the year
20000):
8444 <literal>to_date('
200001130', 'YYYYMMDD')
</literal> will be
8445 interpreted as a
4-digit year; instead use a non-digit
8446 separator after the year, like
8447 <literal>to_date('
20000-
1130', 'YYYY-MMDD')
</literal> or
8448 <literal>to_date('
20000Nov30', 'YYYYMonDD')
</literal>.
8454 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8455 the
<literal>CC
</literal> (century) field is accepted but ignored
8456 if there is a
<literal>YYY
</literal>,
<literal>YYYY
</literal> or
8457 <literal>Y,YYY
</literal> field. If
<literal>CC
</literal> is used with
8458 <literal>YY
</literal> or
<literal>Y
</literal> then the result is
8459 computed as that year in the specified century. If the century is
8460 specified but the year is not, the first year of the century
8467 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8468 weekday names or numbers (
<literal>DAY
</literal>,
<literal>D
</literal>,
8469 and related field types) are accepted but are ignored for purposes of
8470 computing the result. The same is true for quarter
8471 (
<literal>Q
</literal>) fields.
8477 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8478 an ISO
8601 week-numbering date (as distinct from a Gregorian date)
8479 can be specified in one of two ways:
8483 Year, week number, and weekday: for
8484 example
<literal>to_date('
2006-
42-
4', 'IYYY-IW-ID')
</literal>
8485 returns the date
<literal>2006-
10-
19</literal>.
8486 If you omit the weekday it is assumed to be
1 (Monday).
8491 Year and day of year: for example
<literal>to_date('
2006-
291',
8492 'IYYY-IDDD')
</literal> also returns
<literal>2006-
10-
19</literal>.
8498 Attempting to enter a date using a mixture of ISO
8601 week-numbering
8499 fields and Gregorian date fields is nonsensical, and will cause an
8500 error. In the context of an ISO
8601 week-numbering year, the
8501 concept of a
<quote>month
</quote> or
<quote>day of month
</quote> has no
8502 meaning. In the context of a Gregorian year, the ISO week has no
8507 While
<function>to_date
</function> will reject a mixture of
8508 Gregorian and ISO week-numbering date
8509 fields,
<function>to_char
</function> will not, since output format
8510 specifications like
<literal>YYYY-MM-DD (IYYY-IDDD)
</literal> can be
8511 useful. But avoid writing something like
<literal>IYYY-MM-DD
</literal>;
8512 that would yield surprising results near the start of the year.
8513 (See
<xref linkend=
"functions-datetime-extract"/> for more
8521 In
<function>to_timestamp
</function>, millisecond
8522 (
<literal>MS
</literal>) or microsecond (
<literal>US
</literal>)
8523 fields are used as the
8524 seconds digits after the decimal point. For example
8525 <literal>to_timestamp('
12.3', 'SS.MS')
</literal> is not
3 milliseconds,
8526 but
300, because the conversion treats it as
12 +
0.3 seconds.
8527 So, for the format
<literal>SS.MS
</literal>, the input values
8528 <literal>12.3</literal>,
<literal>12.30</literal>,
8529 and
<literal>12.300</literal> specify the
8530 same number of milliseconds. To get three milliseconds, one must write
8531 <literal>12.003</literal>, which the conversion treats as
8532 12 +
0.003 =
12.003 seconds.
8538 <literal>to_timestamp('
15:
12:
02.020.001230', 'HH24:MI:SS.MS.US')
</literal>
8539 is
15 hours,
12 minutes, and
2 seconds +
20 milliseconds +
8540 1230 microseconds =
2.021230 seconds.
8546 <function>to_char(..., 'ID')
</function>'s day of the week numbering
8547 matches the
<function>extract(isodow from ...)
</function> function, but
8548 <function>to_char(..., 'D')
</function>'s does not match
8549 <function>extract(dow from ...)
</function>'s day numbering.
8555 <function>to_char(interval)
</function> formats
<literal>HH
</literal> and
8556 <literal>HH12
</literal> as shown on a
12-hour clock, for example zero hours
8557 and
36 hours both output as
<literal>12</literal>, while
<literal>HH24
</literal>
8558 outputs the full hour value, which can exceed
23 in
8559 an
<type>interval
</type> value.
8567 <xref linkend=
"functions-formatting-numeric-table"/> shows the
8568 template patterns available for formatting numeric values.
8571 <table id=
"functions-formatting-numeric-table">
8572 <title>Template Patterns for Numeric Formatting
</title>
8576 <entry>Pattern
</entry>
8577 <entry>Description
</entry>
8582 <entry><literal>9</literal></entry>
8583 <entry>digit position (can be dropped if insignificant)
</entry>
8586 <entry><literal>0</literal></entry>
8587 <entry>digit position (will not be dropped, even if insignificant)
</entry>
8590 <entry><literal>.
</literal> (period)
</entry>
8591 <entry>decimal point
</entry>
8594 <entry><literal>,
</literal> (comma)
</entry>
8595 <entry>group (thousands) separator
</entry>
8598 <entry><literal>PR
</literal></entry>
8599 <entry>negative value in angle brackets
</entry>
8602 <entry><literal>S
</literal></entry>
8603 <entry>sign anchored to number (uses locale)
</entry>
8606 <entry><literal>L
</literal></entry>
8607 <entry>currency symbol (uses locale)
</entry>
8610 <entry><literal>D
</literal></entry>
8611 <entry>decimal point (uses locale)
</entry>
8614 <entry><literal>G
</literal></entry>
8615 <entry>group separator (uses locale)
</entry>
8618 <entry><literal>MI
</literal></entry>
8619 <entry>minus sign in specified position (if number
< 0)
</entry>
8622 <entry><literal>PL
</literal></entry>
8623 <entry>plus sign in specified position (if number
> 0)
</entry>
8626 <entry><literal>SG
</literal></entry>
8627 <entry>plus/minus sign in specified position
</entry>
8630 <entry><literal>RN
</literal></entry>
8631 <entry>Roman numeral (input between
1 and
3999)
</entry>
8634 <entry><literal>TH
</literal> or
<literal>th
</literal></entry>
8635 <entry>ordinal number suffix
</entry>
8638 <entry><literal>V
</literal></entry>
8639 <entry>shift specified number of digits (see notes)
</entry>
8642 <entry><literal>EEEE
</literal></entry>
8643 <entry>exponent for scientific notation
</entry>
8650 Usage notes for numeric formatting:
8655 <literal>0</literal> specifies a digit position that will always be printed,
8656 even if it contains a leading/trailing zero.
<literal>9</literal> also
8657 specifies a digit position, but if it is a leading zero then it will
8658 be replaced by a space, while if it is a trailing zero and fill mode
8659 is specified then it will be deleted. (For
<function>to_number()
</function>,
8660 these two pattern characters are equivalent.)
8666 If the format provides fewer fractional digits than the number being
8667 formatted,
<function>to_char()
</function> will round the number to
8668 the specified number of fractional digits.
8674 The pattern characters
<literal>S
</literal>,
<literal>L
</literal>,
<literal>D
</literal>,
8675 and
<literal>G
</literal> represent the sign, currency symbol, decimal point,
8676 and thousands separator characters defined by the current locale
8677 (see
<xref linkend=
"guc-lc-monetary"/>
8678 and
<xref linkend=
"guc-lc-numeric"/>). The pattern characters period
8679 and comma represent those exact characters, with the meanings of
8680 decimal point and thousands separator, regardless of locale.
8686 If no explicit provision is made for a sign
8687 in
<function>to_char()
</function>'s pattern, one column will be reserved for
8688 the sign, and it will be anchored to (appear just left of) the
8689 number. If
<literal>S
</literal> appears just left of some
<literal>9</literal>'s,
8690 it will likewise be anchored to the number.
8696 A sign formatted using
<literal>SG
</literal>,
<literal>PL
</literal>, or
8697 <literal>MI
</literal> is not anchored to
8698 the number; for example,
8699 <literal>to_char(-
12, 'MI9999')
</literal> produces
<literal>'-
12'
</literal>
8700 but
<literal>to_char(-
12, 'S9999')
</literal> produces
<literal>'
-
12'
</literal>.
8701 (The Oracle implementation does not allow the use of
8702 <literal>MI
</literal> before
<literal>9</literal>, but rather
8703 requires that
<literal>9</literal> precede
8704 <literal>MI
</literal>.)
8710 <literal>TH
</literal> does not convert values less than zero
8711 and does not convert fractional numbers.
8717 <literal>PL
</literal>,
<literal>SG
</literal>, and
8718 <literal>TH
</literal> are
<productname>PostgreSQL
</productname>
8725 In
<function>to_number
</function>, if non-data template patterns such
8726 as
<literal>L
</literal> or
<literal>TH
</literal> are used, the
8727 corresponding number of input characters are skipped, whether or not
8728 they match the template pattern, unless they are data characters
8729 (that is, digits, sign, decimal point, or comma). For
8730 example,
<literal>TH
</literal> would skip two non-data characters.
8736 <literal>V
</literal> with
<function>to_char
</function>
8737 multiplies the input values by
8738 <literal>10^
<replaceable>n
</replaceable></literal>, where
8739 <replaceable>n
</replaceable> is the number of digits following
8740 <literal>V
</literal>.
<literal>V
</literal> with
8741 <function>to_number
</function> divides in a similar manner.
8742 <function>to_char
</function> and
<function>to_number
</function>
8743 do not support the use of
8744 <literal>V
</literal> combined with a decimal point
8745 (e.g.,
<literal>99.9V99
</literal> is not allowed).
8751 <literal>EEEE
</literal> (scientific notation) cannot be used in
8752 combination with any of the other formatting patterns or
8753 modifiers other than digit and decimal point patterns, and must be at the end of the format string
8754 (e.g.,
<literal>9.99EEEE
</literal> is a valid pattern).
8761 Certain modifiers can be applied to any template pattern to alter its
8762 behavior. For example,
<literal>FM99.99
</literal>
8763 is the
<literal>99.99</literal> pattern with the
8764 <literal>FM
</literal> modifier.
8765 <xref linkend=
"functions-formatting-numericmod-table"/> shows the
8766 modifier patterns for numeric formatting.
8769 <table id=
"functions-formatting-numericmod-table">
8770 <title>Template Pattern Modifiers for Numeric Formatting
</title>
8774 <entry>Modifier
</entry>
8775 <entry>Description
</entry>
8776 <entry>Example
</entry>
8781 <entry><literal>FM
</literal> prefix
</entry>
8782 <entry>fill mode (suppress trailing zeroes and padding blanks)
</entry>
8783 <entry><literal>FM99.99
</literal></entry>
8786 <entry><literal>TH
</literal> suffix
</entry>
8787 <entry>upper case ordinal number suffix
</entry>
8788 <entry><literal>999TH
</literal></entry>
8791 <entry><literal>th
</literal> suffix
</entry>
8792 <entry>lower case ordinal number suffix
</entry>
8793 <entry><literal>999th
</literal></entry>
8800 <xref linkend=
"functions-formatting-examples-table"/> shows some
8801 examples of the use of the
<function>to_char
</function> function.
8804 <table id=
"functions-formatting-examples-table">
8805 <title><function>to_char
</function> Examples
</title>
8809 <entry>Expression
</entry>
8810 <entry>Result
</entry>
8815 <entry><literal>to_char(current_timestamp, 'Day,
DD
HH12:MI:SS')
</literal></entry>
8816 <entry><literal>'Tuesday
,
06 05:
39:
18'
</literal></entry>
8819 <entry><literal>to_char(current_timestamp, 'FMDay,
FMDD
HH12:MI:SS')
</literal></entry>
8820 <entry><literal>'Tuesday,
6 05:
39:
18'
</literal></entry>
8823 <entry><literal>to_char(current_timestamp AT TIME ZONE
8824 'UTC', 'YYYY-MM-DD
"T"HH24:MI:SS
"Z"')
</literal></entry>
8825 <entry><literal>'
2022-
12-
06T05:
39:
18Z'
</literal>,
8826 <acronym>ISO
</acronym> 8601 extended format
</entry>
8829 <entry><literal>to_char(-
0.1, '
99.99')
</literal></entry>
8830 <entry><literal>'
-
.10'
</literal></entry>
8833 <entry><literal>to_char(-
0.1, 'FM9.99')
</literal></entry>
8834 <entry><literal>'-
.1'
</literal></entry>
8837 <entry><literal>to_char(-
0.1, 'FM90.99')
</literal></entry>
8838 <entry><literal>'-
0.1'
</literal></entry>
8841 <entry><literal>to_char(
0.1, '
0.9')
</literal></entry>
8842 <entry><literal>'
0.1'
</literal></entry>
8845 <entry><literal>to_char(
12, '
9990999.9')
</literal></entry>
8846 <entry><literal>'
0012.0'
</literal></entry>
8849 <entry><literal>to_char(
12, 'FM9990999.9')
</literal></entry>
8850 <entry><literal>'
0012.'
</literal></entry>
8853 <entry><literal>to_char(
485, '
999')
</literal></entry>
8854 <entry><literal>'
485'
</literal></entry>
8857 <entry><literal>to_char(-
485, '
999')
</literal></entry>
8858 <entry><literal>'-
485'
</literal></entry>
8861 <entry><literal>to_char(
485, '
9 9 9')
</literal></entry>
8862 <entry><literal>'
4 8 5'
</literal></entry>
8865 <entry><literal>to_char(
1485, '
9,
999')
</literal></entry>
8866 <entry><literal>'
1,
485'
</literal></entry>
8869 <entry><literal>to_char(
1485, '
9G999')
</literal></entry>
8870 <entry><literal>'
1 485'
</literal></entry>
8873 <entry><literal>to_char(
148.5, '
999.999')
</literal></entry>
8874 <entry><literal>'
148.500'
</literal></entry>
8877 <entry><literal>to_char(
148.5, 'FM999.999')
</literal></entry>
8878 <entry><literal>'
148.5'
</literal></entry>
8881 <entry><literal>to_char(
148.5, 'FM999.990')
</literal></entry>
8882 <entry><literal>'
148.500'
</literal></entry>
8885 <entry><literal>to_char(
148.5, '
999D999')
</literal></entry>
8886 <entry><literal>'
148,
500'
</literal></entry>
8889 <entry><literal>to_char(
3148.5, '
9G999D999')
</literal></entry>
8890 <entry><literal>'
3 148,
500'
</literal></entry>
8893 <entry><literal>to_char(-
485, '
999S')
</literal></entry>
8894 <entry><literal>'
485-'
</literal></entry>
8897 <entry><literal>to_char(-
485, '
999MI')
</literal></entry>
8898 <entry><literal>'
485-'
</literal></entry>
8901 <entry><literal>to_char(
485, '
999MI')
</literal></entry>
8902 <entry><literal>'
485 '
</literal></entry>
8905 <entry><literal>to_char(
485, 'FM999MI')
</literal></entry>
8906 <entry><literal>'
485'
</literal></entry>
8909 <entry><literal>to_char(
485, 'PL999')
</literal></entry>
8910 <entry><literal>'+
485'
</literal></entry>
8913 <entry><literal>to_char(
485, 'SG999')
</literal></entry>
8914 <entry><literal>'+
485'
</literal></entry>
8917 <entry><literal>to_char(-
485, 'SG999')
</literal></entry>
8918 <entry><literal>'-
485'
</literal></entry>
8921 <entry><literal>to_char(-
485, '
9SG99')
</literal></entry>
8922 <entry><literal>'
4-
85'
</literal></entry>
8925 <entry><literal>to_char(-
485, '
999PR')
</literal></entry>
8926 <entry><literal>'
<485>'
</literal></entry>
8929 <entry><literal>to_char(
485, 'L999')
</literal></entry>
8930 <entry><literal>'DM
485'
</literal></entry>
8933 <entry><literal>to_char(
485, 'RN')
</literal></entry>
8934 <entry><literal>'
CDLXXXV'
</literal></entry>
8937 <entry><literal>to_char(
485, 'FMRN')
</literal></entry>
8938 <entry><literal>'CDLXXXV'
</literal></entry>
8941 <entry><literal>to_char(
5.2, 'FMRN')
</literal></entry>
8942 <entry><literal>'V'
</literal></entry>
8945 <entry><literal>to_char(
482, '
999th')
</literal></entry>
8946 <entry><literal>'
482nd'
</literal></entry>
8949 <entry><literal>to_char(
485, '
"Good number:"999')
</literal></entry>
8950 <entry><literal>'Good
number:
485'
</literal></entry>
8953 <entry><literal>to_char(
485.8, '
"Pre:"999" Post:" .999')
</literal></entry>
8954 <entry><literal>'Pre:
485 Post:
.800'
</literal></entry>
8957 <entry><literal>to_char(
12, '
99V999')
</literal></entry>
8958 <entry><literal>'
12000'
</literal></entry>
8961 <entry><literal>to_char(
12.4, '
99V999')
</literal></entry>
8962 <entry><literal>'
12400'
</literal></entry>
8965 <entry><literal>to_char(
12.45, '
99V9')
</literal></entry>
8966 <entry><literal>'
125'
</literal></entry>
8969 <entry><literal>to_char(
0.0004859, '
9.99EEEE')
</literal></entry>
8970 <entry><literal>'
4.86e-04'
</literal></entry>
8979 <sect1 id=
"functions-datetime">
8980 <title>Date/Time Functions and Operators
</title>
8983 <xref linkend=
"functions-datetime-table"/> shows the available
8984 functions for date/time value processing, with details appearing in
8985 the following subsections.
<xref
8986 linkend=
"operators-datetime-table"/> illustrates the behaviors of
8987 the basic arithmetic operators (
<literal>+
</literal>,
8988 <literal>*
</literal>, etc.). For formatting functions, refer to
8989 <xref linkend=
"functions-formatting"/>. You should be familiar with
8990 the background information on date/time data types from
<xref
8991 linkend=
"datatype-datetime"/>.
8995 In addition, the usual comparison operators shown in
8996 <xref linkend=
"functions-comparison-op-table"/> are available for the
8997 date/time types. Dates and timestamps (with or without time zone) are
8998 all comparable, while times (with or without time zone) and intervals
8999 can only be compared to other values of the same data type. When
9000 comparing a timestamp without time zone to a timestamp with time zone,
9001 the former value is assumed to be given in the time zone specified by
9002 the
<xref linkend=
"guc-timezone"/> configuration parameter, and is
9003 rotated to UTC for comparison to the latter value (which is already
9004 in UTC internally). Similarly, a date value is assumed to represent
9005 midnight in the
<varname>TimeZone
</varname> zone when comparing it
9010 All the functions and operators described below that take
<type>time
</type> or
<type>timestamp
</type>
9011 inputs actually come in two variants: one that takes
<type>time with time zone
</type> or
<type>timestamp
9012 with time zone
</type>, and one that takes
<type>time without time zone
</type> or
<type>timestamp without time zone
</type>.
9013 For brevity, these variants are not shown separately. Also, the
9014 <literal>+
</literal> and
<literal>*
</literal> operators come in commutative pairs (for
9015 example both
<type>date
</type> <literal>+
</literal> <type>integer
</type>
9016 and
<type>integer
</type> <literal>+
</literal> <type>date
</type>); we show
9017 only one of each such pair.
9020 <table id=
"operators-datetime-table">
9021 <title>Date/Time Operators
</title>
9026 <entry role=
"func_table_entry"><para role=
"func_signature">
9040 <entry role=
"func_table_entry"><para role=
"func_signature">
9041 <type>date
</type> <literal>+
</literal> <type>integer
</type>
9042 <returnvalue>date
</returnvalue>
9045 Add a number of days to a date
9048 <literal>date '
2001-
09-
28' +
7</literal>
9049 <returnvalue>2001-
10-
05</returnvalue>
9054 <entry role=
"func_table_entry"><para role=
"func_signature">
9055 <type>date
</type> <literal>+
</literal> <type>interval
</type>
9056 <returnvalue>timestamp
</returnvalue>
9059 Add an interval to a date
9062 <literal>date '
2001-
09-
28' + interval '
1 hour'
</literal>
9063 <returnvalue>2001-
09-
28 01:
00:
00</returnvalue>
9068 <entry role=
"func_table_entry"><para role=
"func_signature">
9069 <type>date
</type> <literal>+
</literal> <type>time
</type>
9070 <returnvalue>timestamp
</returnvalue>
9073 Add a time-of-day to a date
9076 <literal>date '
2001-
09-
28' + time '
03:
00'
</literal>
9077 <returnvalue>2001-
09-
28 03:
00:
00</returnvalue>
9082 <entry role=
"func_table_entry"><para role=
"func_signature">
9083 <type>interval
</type> <literal>+
</literal> <type>interval
</type>
9084 <returnvalue>interval
</returnvalue>
9090 <literal>interval '
1 day' + interval '
1 hour'
</literal>
9091 <returnvalue>1 day
01:
00:
00</returnvalue>
9096 <entry role=
"func_table_entry"><para role=
"func_signature">
9097 <type>timestamp
</type> <literal>+
</literal> <type>interval
</type>
9098 <returnvalue>timestamp
</returnvalue>
9101 Add an interval to a timestamp
9104 <literal>timestamp '
2001-
09-
28 01:
00' + interval '
23 hours'
</literal>
9105 <returnvalue>2001-
09-
29 00:
00:
00</returnvalue>
9110 <entry role=
"func_table_entry"><para role=
"func_signature">
9111 <type>time
</type> <literal>+
</literal> <type>interval
</type>
9112 <returnvalue>time
</returnvalue>
9115 Add an interval to a time
9118 <literal>time '
01:
00' + interval '
3 hours'
</literal>
9119 <returnvalue>04:
00:
00</returnvalue>
9124 <entry role=
"func_table_entry"><para role=
"func_signature">
9125 <literal>-
</literal> <type>interval
</type>
9126 <returnvalue>interval
</returnvalue>
9132 <literal>- interval '
23 hours'
</literal>
9133 <returnvalue>-
23:
00:
00</returnvalue>
9138 <entry role=
"func_table_entry"><para role=
"func_signature">
9139 <type>date
</type> <literal>-
</literal> <type>date
</type>
9140 <returnvalue>integer
</returnvalue>
9143 Subtract dates, producing the number of days elapsed
9146 <literal>date '
2001-
10-
01' - date '
2001-
09-
28'
</literal>
9147 <returnvalue>3</returnvalue>
9152 <entry role=
"func_table_entry"><para role=
"func_signature">
9153 <type>date
</type> <literal>-
</literal> <type>integer
</type>
9154 <returnvalue>date
</returnvalue>
9157 Subtract a number of days from a date
9160 <literal>date '
2001-
10-
01' -
7</literal>
9161 <returnvalue>2001-
09-
24</returnvalue>
9166 <entry role=
"func_table_entry"><para role=
"func_signature">
9167 <type>date
</type> <literal>-
</literal> <type>interval
</type>
9168 <returnvalue>timestamp
</returnvalue>
9171 Subtract an interval from a date
9174 <literal>date '
2001-
09-
28' - interval '
1 hour'
</literal>
9175 <returnvalue>2001-
09-
27 23:
00:
00</returnvalue>
9180 <entry role=
"func_table_entry"><para role=
"func_signature">
9181 <type>time
</type> <literal>-
</literal> <type>time
</type>
9182 <returnvalue>interval
</returnvalue>
9188 <literal>time '
05:
00' - time '
03:
00'
</literal>
9189 <returnvalue>02:
00:
00</returnvalue>
9194 <entry role=
"func_table_entry"><para role=
"func_signature">
9195 <type>time
</type> <literal>-
</literal> <type>interval
</type>
9196 <returnvalue>time
</returnvalue>
9199 Subtract an interval from a time
9202 <literal>time '
05:
00' - interval '
2 hours'
</literal>
9203 <returnvalue>03:
00:
00</returnvalue>
9208 <entry role=
"func_table_entry"><para role=
"func_signature">
9209 <type>timestamp
</type> <literal>-
</literal> <type>interval
</type>
9210 <returnvalue>timestamp
</returnvalue>
9213 Subtract an interval from a timestamp
9216 <literal>timestamp '
2001-
09-
28 23:
00' - interval '
23 hours'
</literal>
9217 <returnvalue>2001-
09-
28 00:
00:
00</returnvalue>
9222 <entry role=
"func_table_entry"><para role=
"func_signature">
9223 <type>interval
</type> <literal>-
</literal> <type>interval
</type>
9224 <returnvalue>interval
</returnvalue>
9230 <literal>interval '
1 day' - interval '
1 hour'
</literal>
9231 <returnvalue>1 day -
01:
00:
00</returnvalue>
9236 <entry role=
"func_table_entry"><para role=
"func_signature">
9237 <type>timestamp
</type> <literal>-
</literal> <type>timestamp
</type>
9238 <returnvalue>interval
</returnvalue>
9241 Subtract timestamps (converting
24-hour intervals into days,
9243 linkend=
"function-justify-hours"><function>justify_hours()
</function></link>)
9246 <literal>timestamp '
2001-
09-
29 03:
00' - timestamp '
2001-
07-
27 12:
00'
</literal>
9247 <returnvalue>63 days
15:
00:
00</returnvalue>
9252 <entry role=
"func_table_entry"><para role=
"func_signature">
9253 <type>interval
</type> <literal>*
</literal> <type>double precision
</type>
9254 <returnvalue>interval
</returnvalue>
9257 Multiply an interval by a scalar
9260 <literal>interval '
1 second' *
900</literal>
9261 <returnvalue>00:
15:
00</returnvalue>
9264 <literal>interval '
1 day' *
21</literal>
9265 <returnvalue>21 days
</returnvalue>
9268 <literal>interval '
1 hour' *
3.5</literal>
9269 <returnvalue>03:
30:
00</returnvalue>
9274 <entry role=
"func_table_entry"><para role=
"func_signature">
9275 <type>interval
</type> <literal>/
</literal> <type>double precision
</type>
9276 <returnvalue>interval
</returnvalue>
9279 Divide an interval by a scalar
9282 <literal>interval '
1 hour' /
1.5</literal>
9283 <returnvalue>00:
40:
00</returnvalue>
9290 <table id=
"functions-datetime-table">
9291 <title>Date/Time Functions
</title>
9295 <entry role=
"func_table_entry"><para role=
"func_signature">
9309 <entry role=
"func_table_entry"><para role=
"func_signature">
9311 <primary>age
</primary>
9313 <function>age
</function> (
<type>timestamp
</type>,
<type>timestamp
</type> )
9314 <returnvalue>interval
</returnvalue>
9317 Subtract arguments, producing a
<quote>symbolic
</quote> result that
9318 uses years and months, rather than just days
9321 <literal>age(timestamp '
2001-
04-
10', timestamp '
1957-
06-
13')
</literal>
9322 <returnvalue>43 years
9 mons
27 days
</returnvalue>
9327 <entry role=
"func_table_entry"><para role=
"func_signature">
9328 <function>age
</function> (
<type>timestamp
</type> )
9329 <returnvalue>interval
</returnvalue>
9332 Subtract argument from
<function>current_date
</function> (at midnight)
9335 <literal>age(timestamp '
1957-
06-
13')
</literal>
9336 <returnvalue>62 years
6 mons
10 days
</returnvalue>
9341 <entry role=
"func_table_entry"><para role=
"func_signature">
9343 <primary>clock_timestamp
</primary>
9345 <function>clock_timestamp
</function> ( )
9346 <returnvalue>timestamp with time zone
</returnvalue>
9349 Current date and time (changes during statement execution);
9350 see
<xref linkend=
"functions-datetime-current"/>
9353 <literal>clock_timestamp()
</literal>
9354 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9359 <entry role=
"func_table_entry"><para role=
"func_signature">
9361 <primary>current_date
</primary>
9363 <function>current_date
</function>
9364 <returnvalue>date
</returnvalue>
9367 Current date; see
<xref linkend=
"functions-datetime-current"/>
9370 <literal>current_date
</literal>
9371 <returnvalue>2019-
12-
23</returnvalue>
9376 <entry role=
"func_table_entry"><para role=
"func_signature">
9378 <primary>current_time
</primary>
9380 <function>current_time
</function>
9381 <returnvalue>time with time zone
</returnvalue>
9384 Current time of day; see
<xref linkend=
"functions-datetime-current"/>
9387 <literal>current_time
</literal>
9388 <returnvalue>14:
39:
53.662522-
05</returnvalue>
9393 <entry role=
"func_table_entry"><para role=
"func_signature">
9394 <function>current_time
</function> (
<type>integer
</type> )
9395 <returnvalue>time with time zone
</returnvalue>
9398 Current time of day, with limited precision;
9399 see
<xref linkend=
"functions-datetime-current"/>
9402 <literal>current_time(
2)
</literal>
9403 <returnvalue>14:
39:
53.66-
05</returnvalue>
9408 <entry role=
"func_table_entry"><para role=
"func_signature">
9410 <primary>current_timestamp
</primary>
9412 <function>current_timestamp
</function>
9413 <returnvalue>timestamp with time zone
</returnvalue>
9416 Current date and time (start of current transaction);
9417 see
<xref linkend=
"functions-datetime-current"/>
9420 <literal>current_timestamp
</literal>
9421 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9426 <entry role=
"func_table_entry"><para role=
"func_signature">
9427 <function>current_timestamp
</function> (
<type>integer
</type> )
9428 <returnvalue>timestamp with time zone
</returnvalue>
9431 Current date and time (start of current transaction), with limited precision;
9432 see
<xref linkend=
"functions-datetime-current"/>
9435 <literal>current_timestamp(
0)
</literal>
9436 <returnvalue>2019-
12-
23 14:
39:
53-
05</returnvalue>
9441 <entry role=
"func_table_entry"><para role=
"func_signature">
9443 <primary>date_add
</primary>
9445 <function>date_add
</function> (
<type>timestamp with time zone
</type>,
<type>interval
</type> <optional>,
<type>text
</type> </optional> )
9446 <returnvalue>timestamp with time zone
</returnvalue>
9449 Add an
<type>interval
</type> to a
<type>timestamp with time
9450 zone
</type>, computing times of day and daylight-savings adjustments
9451 according to the time zone named by the third argument, or the
9452 current
<xref linkend=
"guc-timezone"/> setting if that is omitted.
9453 The form with two arguments is equivalent to the
<type>timestamp with
9454 time zone
</type> <literal>+
</literal> <type>interval
</type> operator.
9457 <literal>date_add('
2021-
10-
31 00:
00:
00+
02'::timestamptz, '
1 day'::interval, 'Europe/Warsaw')
</literal>
9458 <returnvalue>2021-
10-
31 23:
00:
00+
00</returnvalue>
9463 <entry role=
"func_table_entry"><para role=
"func_signature">
9464 <function>date_bin
</function> (
<type>interval
</type>,
<type>timestamp
</type>,
<type>timestamp
</type> )
9465 <returnvalue>timestamp
</returnvalue>
9468 Bin input into specified interval aligned with specified origin; see
<xref linkend=
"functions-datetime-bin"/>
9471 <literal>date_bin('
15 minutes', timestamp '
2001-
02-
16 20:
38:
40', timestamp '
2001-
02-
16 20:
05:
00')
</literal>
9472 <returnvalue>2001-
02-
16 20:
35:
00</returnvalue>
9477 <entry role=
"func_table_entry"><para role=
"func_signature">
9479 <primary>date_part
</primary>
9481 <function>date_part
</function> (
<type>text
</type>,
<type>timestamp
</type> )
9482 <returnvalue>double precision
</returnvalue>
9485 Get timestamp subfield (equivalent to
<function>extract
</function>);
9486 see
<xref linkend=
"functions-datetime-extract"/>
9489 <literal>date_part('hour', timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9490 <returnvalue>20</returnvalue>
9495 <entry role=
"func_table_entry"><para role=
"func_signature">
9496 <function>date_part
</function> (
<type>text
</type>,
<type>interval
</type> )
9497 <returnvalue>double precision
</returnvalue>
9500 Get interval subfield (equivalent to
<function>extract
</function>);
9501 see
<xref linkend=
"functions-datetime-extract"/>
9504 <literal>date_part('month', interval '
2 years
3 months')
</literal>
9505 <returnvalue>3</returnvalue>
9510 <entry role=
"func_table_entry"><para role=
"func_signature">
9512 <primary>date_subtract
</primary>
9514 <function>date_subtract
</function> (
<type>timestamp with time zone
</type>,
<type>interval
</type> <optional>,
<type>text
</type> </optional> )
9515 <returnvalue>timestamp with time zone
</returnvalue>
9518 Subtract an
<type>interval
</type> from a
<type>timestamp with time
9519 zone
</type>, computing times of day and daylight-savings adjustments
9520 according to the time zone named by the third argument, or the
9521 current
<xref linkend=
"guc-timezone"/> setting if that is omitted.
9522 The form with two arguments is equivalent to the
<type>timestamp with
9523 time zone
</type> <literal>-
</literal> <type>interval
</type> operator.
9526 <literal>date_subtract('
2021-
11-
01 00:
00:
00+
01'::timestamptz, '
1 day'::interval, 'Europe/Warsaw')
</literal>
9527 <returnvalue>2021-
10-
30 22:
00:
00+
00</returnvalue>
9532 <entry role=
"func_table_entry"><para role=
"func_signature">
9534 <primary>date_trunc
</primary>
9536 <function>date_trunc
</function> (
<type>text
</type>,
<type>timestamp
</type> )
9537 <returnvalue>timestamp
</returnvalue>
9540 Truncate to specified precision; see
<xref linkend=
"functions-datetime-trunc"/>
9543 <literal>date_trunc('hour', timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9544 <returnvalue>2001-
02-
16 20:
00:
00</returnvalue>
9549 <entry role=
"func_table_entry"><para role=
"func_signature">
9550 <function>date_trunc
</function> (
<type>text
</type>,
<type>timestamp with time zone
</type>,
<type>text
</type> )
9551 <returnvalue>timestamp with time zone
</returnvalue>
9554 Truncate to specified precision in the specified time zone; see
9555 <xref linkend=
"functions-datetime-trunc"/>
9558 <literal>date_trunc('day', timestamptz '
2001-
02-
16 20:
38:
40+
00', 'Australia/Sydney')
</literal>
9559 <returnvalue>2001-
02-
16 13:
00:
00+
00</returnvalue>
9564 <entry role=
"func_table_entry"><para role=
"func_signature">
9565 <function>date_trunc
</function> (
<type>text
</type>,
<type>interval
</type> )
9566 <returnvalue>interval
</returnvalue>
9569 Truncate to specified precision; see
9570 <xref linkend=
"functions-datetime-trunc"/>
9573 <literal>date_trunc('hour', interval '
2 days
3 hours
40 minutes')
</literal>
9574 <returnvalue>2 days
03:
00:
00</returnvalue>
9579 <entry role=
"func_table_entry"><para role=
"func_signature">
9581 <primary>extract
</primary>
9583 <function>extract
</function> (
<parameter>field
</parameter> <literal>from
</literal> <type>timestamp
</type> )
9584 <returnvalue>numeric
</returnvalue>
9587 Get timestamp subfield; see
<xref linkend=
"functions-datetime-extract"/>
9590 <literal>extract(hour from timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9591 <returnvalue>20</returnvalue>
9596 <entry role=
"func_table_entry"><para role=
"func_signature">
9597 <function>extract
</function> (
<parameter>field
</parameter> <literal>from
</literal> <type>interval
</type> )
9598 <returnvalue>numeric
</returnvalue>
9601 Get interval subfield; see
<xref linkend=
"functions-datetime-extract"/>
9604 <literal>extract(month from interval '
2 years
3 months')
</literal>
9605 <returnvalue>3</returnvalue>
9610 <entry role=
"func_table_entry"><para role=
"func_signature">
9612 <primary>isfinite
</primary>
9614 <function>isfinite
</function> (
<type>date
</type> )
9615 <returnvalue>boolean
</returnvalue>
9618 Test for finite date (not +/-infinity)
9621 <literal>isfinite(date '
2001-
02-
16')
</literal>
9622 <returnvalue>true
</returnvalue>
9627 <entry role=
"func_table_entry"><para role=
"func_signature">
9628 <function>isfinite
</function> (
<type>timestamp
</type> )
9629 <returnvalue>boolean
</returnvalue>
9632 Test for finite timestamp (not +/-infinity)
9635 <literal>isfinite(timestamp 'infinity')
</literal>
9636 <returnvalue>false
</returnvalue>
9641 <entry role=
"func_table_entry"><para role=
"func_signature">
9642 <function>isfinite
</function> (
<type>interval
</type> )
9643 <returnvalue>boolean
</returnvalue>
9646 Test for finite interval (not +/-infinity)
9649 <literal>isfinite(interval '
4 hours')
</literal>
9650 <returnvalue>true
</returnvalue>
9655 <entry role=
"func_table_entry"><para role=
"func_signature">
9656 <indexterm id=
"function-justify-days">
9657 <primary>justify_days
</primary>
9659 <function>justify_days
</function> (
<type>interval
</type> )
9660 <returnvalue>interval
</returnvalue>
9663 Adjust interval, converting
30-day time periods to months
9666 <literal>justify_days(interval '
1 year
65 days')
</literal>
9667 <returnvalue>1 year
2 mons
5 days
</returnvalue>
9672 <entry role=
"func_table_entry"><para role=
"func_signature">
9673 <indexterm id=
"function-justify-hours">
9674 <primary>justify_hours
</primary>
9676 <function>justify_hours
</function> (
<type>interval
</type> )
9677 <returnvalue>interval
</returnvalue>
9680 Adjust interval, converting
24-hour time periods to days
9683 <literal>justify_hours(interval '
50 hours
10 minutes')
</literal>
9684 <returnvalue>2 days
02:
10:
00</returnvalue>
9689 <entry role=
"func_table_entry"><para role=
"func_signature">
9691 <primary>justify_interval
</primary>
9693 <function>justify_interval
</function> (
<type>interval
</type> )
9694 <returnvalue>interval
</returnvalue>
9697 Adjust interval using
<function>justify_days
</function>
9698 and
<function>justify_hours
</function>, with additional sign
9702 <literal>justify_interval(interval '
1 mon -
1 hour')
</literal>
9703 <returnvalue>29 days
23:
00:
00</returnvalue>
9708 <entry role=
"func_table_entry"><para role=
"func_signature">
9710 <primary>localtime
</primary>
9712 <function>localtime
</function>
9713 <returnvalue>time
</returnvalue>
9716 Current time of day;
9717 see
<xref linkend=
"functions-datetime-current"/>
9720 <literal>localtime
</literal>
9721 <returnvalue>14:
39:
53.662522</returnvalue>
9726 <entry role=
"func_table_entry"><para role=
"func_signature">
9727 <function>localtime
</function> (
<type>integer
</type> )
9728 <returnvalue>time
</returnvalue>
9731 Current time of day, with limited precision;
9732 see
<xref linkend=
"functions-datetime-current"/>
9735 <literal>localtime(
0)
</literal>
9736 <returnvalue>14:
39:
53</returnvalue>
9741 <entry role=
"func_table_entry"><para role=
"func_signature">
9743 <primary>localtimestamp
</primary>
9745 <function>localtimestamp
</function>
9746 <returnvalue>timestamp
</returnvalue>
9749 Current date and time (start of current transaction);
9750 see
<xref linkend=
"functions-datetime-current"/>
9753 <literal>localtimestamp
</literal>
9754 <returnvalue>2019-
12-
23 14:
39:
53.662522</returnvalue>
9759 <entry role=
"func_table_entry"><para role=
"func_signature">
9760 <function>localtimestamp
</function> (
<type>integer
</type> )
9761 <returnvalue>timestamp
</returnvalue>
9764 Current date and time (start of current
9765 transaction), with limited precision;
9766 see
<xref linkend=
"functions-datetime-current"/>
9769 <literal>localtimestamp(
2)
</literal>
9770 <returnvalue>2019-
12-
23 14:
39:
53.66</returnvalue>
9775 <entry role=
"func_table_entry"><para role=
"func_signature">
9777 <primary>make_date
</primary>
9779 <function>make_date
</function> (
<parameter>year
</parameter> <type>int
</type>,
9780 <parameter>month
</parameter> <type>int
</type>,
9781 <parameter>day
</parameter> <type>int
</type> )
9782 <returnvalue>date
</returnvalue>
9785 Create date from year, month and day fields
9786 (negative years signify BC)
9789 <literal>make_date(
2013,
7,
15)
</literal>
9790 <returnvalue>2013-
07-
15</returnvalue>
9795 <entry role=
"func_table_entry"><para role=
"func_signature"><indexterm>
9796 <primary>make_interval
</primary>
9798 <function>make_interval
</function> (
<optional> <parameter>years
</parameter> <type>int
</type>
9799 <optional>,
<parameter>months
</parameter> <type>int
</type>
9800 <optional>,
<parameter>weeks
</parameter> <type>int
</type>
9801 <optional>,
<parameter>days
</parameter> <type>int
</type>
9802 <optional>,
<parameter>hours
</parameter> <type>int
</type>
9803 <optional>,
<parameter>mins
</parameter> <type>int
</type>
9804 <optional>,
<parameter>secs
</parameter> <type>double precision
</type>
9805 </optional></optional></optional></optional></optional></optional></optional> )
9806 <returnvalue>interval
</returnvalue>
9809 Create interval from years, months, weeks, days, hours, minutes and
9810 seconds fields, each of which can default to zero
9813 <literal>make_interval(days =
> 10)
</literal>
9814 <returnvalue>10 days
</returnvalue>
9819 <entry role=
"func_table_entry"><para role=
"func_signature">
9821 <primary>make_time
</primary>
9823 <function>make_time
</function> (
<parameter>hour
</parameter> <type>int
</type>,
9824 <parameter>min
</parameter> <type>int
</type>,
9825 <parameter>sec
</parameter> <type>double precision
</type> )
9826 <returnvalue>time
</returnvalue>
9829 Create time from hour, minute and seconds fields
9832 <literal>make_time(
8,
15,
23.5)
</literal>
9833 <returnvalue>08:
15:
23.5</returnvalue>
9838 <entry role=
"func_table_entry"><para role=
"func_signature">
9840 <primary>make_timestamp
</primary>
9842 <function>make_timestamp
</function> (
<parameter>year
</parameter> <type>int
</type>,
9843 <parameter>month
</parameter> <type>int
</type>,
9844 <parameter>day
</parameter> <type>int
</type>,
9845 <parameter>hour
</parameter> <type>int
</type>,
9846 <parameter>min
</parameter> <type>int
</type>,
9847 <parameter>sec
</parameter> <type>double precision
</type> )
9848 <returnvalue>timestamp
</returnvalue>
9851 Create timestamp from year, month, day, hour, minute and seconds fields
9852 (negative years signify BC)
9855 <literal>make_timestamp(
2013,
7,
15,
8,
15,
23.5)
</literal>
9856 <returnvalue>2013-
07-
15 08:
15:
23.5</returnvalue>
9861 <entry role=
"func_table_entry"><para role=
"func_signature">
9863 <primary>make_timestamptz
</primary>
9865 <function>make_timestamptz
</function> (
<parameter>year
</parameter> <type>int
</type>,
9866 <parameter>month
</parameter> <type>int
</type>,
9867 <parameter>day
</parameter> <type>int
</type>,
9868 <parameter>hour
</parameter> <type>int
</type>,
9869 <parameter>min
</parameter> <type>int
</type>,
9870 <parameter>sec
</parameter> <type>double precision
</type>
9871 <optional>,
<parameter>timezone
</parameter> <type>text
</type> </optional> )
9872 <returnvalue>timestamp with time zone
</returnvalue>
9875 Create timestamp with time zone from year, month, day, hour, minute
9876 and seconds fields (negative years signify BC).
9877 If
<parameter>timezone
</parameter> is not
9878 specified, the current time zone is used; the examples assume the
9879 session time zone is
<literal>Europe/London
</literal>
9882 <literal>make_timestamptz(
2013,
7,
15,
8,
15,
23.5)
</literal>
9883 <returnvalue>2013-
07-
15 08:
15:
23.5+
01</returnvalue>
9886 <literal>make_timestamptz(
2013,
7,
15,
8,
15,
23.5, 'America/New_York')
</literal>
9887 <returnvalue>2013-
07-
15 13:
15:
23.5+
01</returnvalue>
9892 <entry role=
"func_table_entry"><para role=
"func_signature">
9894 <primary>now
</primary>
9896 <function>now
</function> ( )
9897 <returnvalue>timestamp with time zone
</returnvalue>
9900 Current date and time (start of current transaction);
9901 see
<xref linkend=
"functions-datetime-current"/>
9904 <literal>now()
</literal>
9905 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9910 <entry role=
"func_table_entry"><para role=
"func_signature">
9912 <primary>statement_timestamp
</primary>
9914 <function>statement_timestamp
</function> ( )
9915 <returnvalue>timestamp with time zone
</returnvalue>
9918 Current date and time (start of current statement);
9919 see
<xref linkend=
"functions-datetime-current"/>
9922 <literal>statement_timestamp()
</literal>
9923 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9928 <entry role=
"func_table_entry"><para role=
"func_signature">
9930 <primary>timeofday
</primary>
9932 <function>timeofday
</function> ( )
9933 <returnvalue>text
</returnvalue>
9936 Current date and time
9937 (like
<function>clock_timestamp
</function>, but as a
<type>text
</type> string);
9938 see
<xref linkend=
"functions-datetime-current"/>
9941 <literal>timeofday()
</literal>
9942 <returnvalue>Mon Dec
23 14:
39:
53.662522 2019 EST
</returnvalue>
9947 <entry role=
"func_table_entry"><para role=
"func_signature">
9949 <primary>transaction_timestamp
</primary>
9951 <function>transaction_timestamp
</function> ( )
9952 <returnvalue>timestamp with time zone
</returnvalue>
9955 Current date and time (start of current transaction);
9956 see
<xref linkend=
"functions-datetime-current"/>
9959 <literal>transaction_timestamp()
</literal>
9960 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9965 <entry role=
"func_table_entry"><para role=
"func_signature">
9967 <primary>to_timestamp
</primary>
9969 <function>to_timestamp
</function> (
<type>double precision
</type> )
9970 <returnvalue>timestamp with time zone
</returnvalue>
9973 Convert Unix epoch (seconds since
1970-
01-
01 00:
00:
00+
00) to
9974 timestamp with time zone
9977 <literal>to_timestamp(
1284352323)
</literal>
9978 <returnvalue>2010-
09-
13 04:
32:
03+
00</returnvalue>
9987 <primary>OVERLAPS
</primary>
9989 In addition to these functions, the SQL
<literal>OVERLAPS
</literal> operator is
9992 (
<replaceable>start1
</replaceable>,
<replaceable>end1
</replaceable>) OVERLAPS (
<replaceable>start2
</replaceable>,
<replaceable>end2
</replaceable>)
9993 (
<replaceable>start1
</replaceable>,
<replaceable>length1
</replaceable>) OVERLAPS (
<replaceable>start2
</replaceable>,
<replaceable>length2
</replaceable>)
9995 This expression yields true when two time periods (defined by their
9996 endpoints) overlap, false when they do not overlap. The endpoints
9997 can be specified as pairs of dates, times, or time stamps; or as
9998 a date, time, or time stamp followed by an interval. When a pair
9999 of values is provided, either the start or the end can be written
10000 first;
<literal>OVERLAPS
</literal> automatically takes the earlier value
10001 of the pair as the start. Each time period is considered to
10002 represent the half-open interval
<replaceable>start
</replaceable> <literal><=
</literal>
10003 <replaceable>time
</replaceable> <literal><</literal> <replaceable>end
</replaceable>, unless
10004 <replaceable>start
</replaceable> and
<replaceable>end
</replaceable> are equal in which case it
10005 represents that single time instant. This means for instance that two
10006 time periods with only an endpoint in common do not overlap.
10010 SELECT (DATE '
2001-
02-
16', DATE '
2001-
12-
21') OVERLAPS
10011 (DATE '
2001-
10-
30', DATE '
2002-
10-
30');
10012 <lineannotation>Result:
</lineannotation><computeroutput>true
</computeroutput>
10013 SELECT (DATE '
2001-
02-
16', INTERVAL '
100 days') OVERLAPS
10014 (DATE '
2001-
10-
30', DATE '
2002-
10-
30');
10015 <lineannotation>Result:
</lineannotation><computeroutput>false
</computeroutput>
10016 SELECT (DATE '
2001-
10-
29', DATE '
2001-
10-
30') OVERLAPS
10017 (DATE '
2001-
10-
30', DATE '
2001-
10-
31');
10018 <lineannotation>Result:
</lineannotation><computeroutput>false
</computeroutput>
10019 SELECT (DATE '
2001-
10-
30', DATE '
2001-
10-
30') OVERLAPS
10020 (DATE '
2001-
10-
30', DATE '
2001-
10-
31');
10021 <lineannotation>Result:
</lineannotation><computeroutput>true
</computeroutput>
10025 When adding an
<type>interval
</type> value to (or subtracting an
10026 <type>interval
</type> value from) a
<type>timestamp
</type>
10027 or
<type>timestamp with time zone
</type> value, the months, days, and
10028 microseconds fields of the
<type>interval
</type> value are handled in turn.
10029 First, a nonzero months field advances or decrements the date of the
10030 timestamp by the indicated number of months, keeping the day of month the
10031 same unless it would be past the end of the new month, in which case the
10032 last day of that month is used. (For example, March
31 plus
1 month
10033 becomes April
30, but March
31 plus
2 months becomes May
31.)
10034 Then the days field advances or decrements the date of the timestamp by
10035 the indicated number of days. In both these steps the local time of day
10036 is kept the same. Finally, if there is a nonzero microseconds field, it
10037 is added or subtracted literally.
10038 When doing arithmetic on a
<type>timestamp with time zone
</type> value in
10039 a time zone that recognizes DST, this means that adding or subtracting
10040 (say)
<literal>interval '
1 day'
</literal> does not necessarily have the
10041 same result as adding or subtracting
<literal>interval '
24
10043 For example, with the session time zone set
10044 to
<literal>America/Denver
</literal>:
10046 SELECT timestamp with time zone '
2005-
04-
02 12:
00:
00-
07' + interval '
1 day';
10047 <lineannotation>Result:
</lineannotation><computeroutput>2005-
04-
03 12:
00:
00-
06</computeroutput>
10048 SELECT timestamp with time zone '
2005-
04-
02 12:
00:
00-
07' + interval '
24 hours';
10049 <lineannotation>Result:
</lineannotation><computeroutput>2005-
04-
03 13:
00:
00-
06</computeroutput>
10051 This happens because an hour was skipped due to a change in daylight saving
10052 time at
<literal>2005-
04-
03 02:
00:
00</literal> in time zone
10053 <literal>America/Denver
</literal>.
10057 Note there can be ambiguity in the
<literal>months
</literal> field returned by
10058 <function>age
</function> because different months have different numbers of
10059 days.
<productname>PostgreSQL
</productname>'s approach uses the month from the
10060 earlier of the two dates when calculating partial months. For example,
10061 <literal>age('
2004-
06-
01', '
2004-
04-
30')
</literal> uses April to yield
10062 <literal>1 mon
1 day
</literal>, while using May would yield
<literal>1 mon
2
10063 days
</literal> because May has
31 days, while April has only
30.
10067 Subtraction of dates and timestamps can also be complex. One conceptually
10068 simple way to perform subtraction is to convert each value to a number
10069 of seconds using
<literal>EXTRACT(EPOCH FROM ...)
</literal>, then subtract the
10070 results; this produces the
10071 number of
<emphasis>seconds
</emphasis> between the two values. This will adjust
10072 for the number of days in each month, timezone changes, and daylight
10073 saving time adjustments. Subtraction of date or timestamp
10074 values with the
<quote><literal>-
</literal></quote> operator
10075 returns the number of days (
24-hours) and hours/minutes/seconds
10076 between the values, making the same adjustments. The
<function>age
</function>
10077 function returns years, months, days, and hours/minutes/seconds,
10078 performing field-by-field subtraction and then adjusting for negative
10079 field values. The following queries illustrate the differences in these
10080 approaches. The sample results were produced with
<literal>timezone
10081 = 'US/Eastern'
</literal>; there is a daylight saving time change between the
10086 SELECT EXTRACT(EPOCH FROM timestamptz '
2013-
07-
01 12:
00:
00') -
10087 EXTRACT(EPOCH FROM timestamptz '
2013-
03-
01 12:
00:
00');
10088 <lineannotation>Result:
</lineannotation><computeroutput>10537200.000000</computeroutput>
10089 SELECT (EXTRACT(EPOCH FROM timestamptz '
2013-
07-
01 12:
00:
00') -
10090 EXTRACT(EPOCH FROM timestamptz '
2013-
03-
01 12:
00:
00'))
10092 <lineannotation>Result:
</lineannotation><computeroutput>121.9583333333333333</computeroutput>
10093 SELECT timestamptz '
2013-
07-
01 12:
00:
00' - timestamptz '
2013-
03-
01 12:
00:
00';
10094 <lineannotation>Result:
</lineannotation><computeroutput>121 days
23:
00:
00</computeroutput>
10095 SELECT age(timestamptz '
2013-
07-
01 12:
00:
00', timestamptz '
2013-
03-
01 12:
00:
00');
10096 <lineannotation>Result:
</lineannotation><computeroutput>4 mons
</computeroutput>
10099 <sect2 id=
"functions-datetime-extract">
10100 <title><function>EXTRACT
</function>,
<function>date_part
</function></title>
10103 <primary>date_part
</primary>
10106 <primary>extract
</primary>
10110 EXTRACT(
<replaceable>field
</replaceable> FROM
<replaceable>source
</replaceable>)
10114 The
<function>extract
</function> function retrieves subfields
10115 such as year or hour from date/time values.
10116 <replaceable>source
</replaceable> must be a value expression of
10117 type
<type>timestamp
</type>,
<type>date
</type>,
<type>time
</type>,
10118 or
<type>interval
</type>. (Timestamps and times can be with or
10119 without time zone.)
10120 <replaceable>field
</replaceable> is an identifier or
10121 string that selects what field to extract from the source value.
10122 Not all fields are valid for every input data type; for example, fields
10123 smaller than a day cannot be extracted from a
<type>date
</type>, while
10124 fields of a day or more cannot be extracted from a
<type>time
</type>.
10125 The
<function>extract
</function> function returns values of type
10126 <type>numeric
</type>.
10130 The following are valid field names:
10132 <!-- alphabetical -->
10135 <term><literal>century
</literal></term>
10138 The century; for
<type>interval
</type> values, the year field
10143 SELECT EXTRACT(CENTURY FROM TIMESTAMP '
2000-
12-
16 12:
21:
13');
10144 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10145 SELECT EXTRACT(CENTURY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10146 <lineannotation>Result:
</lineannotation><computeroutput>21</computeroutput>
10147 SELECT EXTRACT(CENTURY FROM DATE '
0001-
01-
01 AD');
10148 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10149 SELECT EXTRACT(CENTURY FROM DATE '
0001-
12-
31 BC');
10150 <lineannotation>Result:
</lineannotation><computeroutput>-
1</computeroutput>
10151 SELECT EXTRACT(CENTURY FROM INTERVAL '
2001 years');
10152 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10158 <term><literal>day
</literal></term>
10161 The day of the month (
1–31); for
<type>interval
</type>
10162 values, the number of days
10166 SELECT EXTRACT(DAY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10167 <lineannotation>Result:
</lineannotation><computeroutput>16</computeroutput>
10168 SELECT EXTRACT(DAY FROM INTERVAL '
40 days
1 minute');
10169 <lineannotation>Result:
</lineannotation><computeroutput>40</computeroutput>
10176 <term><literal>decade
</literal></term>
10179 The year field divided by
10
10183 SELECT EXTRACT(DECADE FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10184 <lineannotation>Result:
</lineannotation><computeroutput>200</computeroutput>
10190 <term><literal>dow
</literal></term>
10193 The day of the week as Sunday (
<literal>0</literal>) to
10194 Saturday (
<literal>6</literal>)
10198 SELECT EXTRACT(DOW FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10199 <lineannotation>Result:
</lineannotation><computeroutput>5</computeroutput>
10202 Note that
<function>extract
</function>'s day of the week numbering
10203 differs from that of the
<function>to_char(...,
10204 'D')
</function> function.
10211 <term><literal>doy
</literal></term>
10214 The day of the year (
1–365/
366)
10218 SELECT EXTRACT(DOY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10219 <lineannotation>Result:
</lineannotation><computeroutput>47</computeroutput>
10225 <term><literal>epoch
</literal></term>
10228 For
<type>timestamp with time zone
</type> values, the
10229 number of seconds since
1970-
01-
01 00:
00:
00 UTC (negative for
10230 timestamps before that);
10231 for
<type>date
</type> and
<type>timestamp
</type> values, the
10232 nominal number of seconds since
1970-
01-
01 00:
00:
00,
10233 without regard to timezone or daylight-savings rules;
10234 for
<type>interval
</type> values, the total number
10235 of seconds in the interval
10239 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40.12-
08');
10240 <lineannotation>Result:
</lineannotation><computeroutput>982384720.120000</computeroutput>
10241 SELECT EXTRACT(EPOCH FROM TIMESTAMP '
2001-
02-
16 20:
38:
40.12');
10242 <lineannotation>Result:
</lineannotation><computeroutput>982355920.120000</computeroutput>
10243 SELECT EXTRACT(EPOCH FROM INTERVAL '
5 days
3 hours');
10244 <lineannotation>Result:
</lineannotation><computeroutput>442800.000000</computeroutput>
10248 You can convert an epoch value back to a
<type>timestamp with time zone
</type>
10249 with
<function>to_timestamp
</function>:
10252 SELECT to_timestamp(
982384720.12);
10253 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
17 04:
38:
40.12+
00</computeroutput>
10257 Beware that applying
<function>to_timestamp
</function> to an epoch
10258 extracted from a
<type>date
</type> or
<type>timestamp
</type> value
10259 could produce a misleading result: the result will effectively
10260 assume that the original value had been given in UTC, which might
10267 <term><literal>hour
</literal></term>
10270 The hour field (
0–23 in timestamps, unrestricted in
10275 SELECT EXTRACT(HOUR FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10276 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10282 <term><literal>isodow
</literal></term>
10285 The day of the week as Monday (
<literal>1</literal>) to
10286 Sunday (
<literal>7</literal>)
10290 SELECT EXTRACT(ISODOW FROM TIMESTAMP '
2001-
02-
18 20:
38:
40');
10291 <lineannotation>Result:
</lineannotation><computeroutput>7</computeroutput>
10294 This is identical to
<literal>dow
</literal> except for Sunday. This
10295 matches the
<acronym>ISO
</acronym> 8601 day of the week numbering.
10302 <term><literal>isoyear
</literal></term>
10305 The
<acronym>ISO
</acronym> 8601 week-numbering year that the date
10310 SELECT EXTRACT(ISOYEAR FROM DATE '
2006-
01-
01');
10311 <lineannotation>Result:
</lineannotation><computeroutput>2005</computeroutput>
10312 SELECT EXTRACT(ISOYEAR FROM DATE '
2006-
01-
02');
10313 <lineannotation>Result:
</lineannotation><computeroutput>2006</computeroutput>
10317 Each
<acronym>ISO
</acronym> 8601 week-numbering year begins with the
10318 Monday of the week containing the
4th of January, so in early
10319 January or late December the
<acronym>ISO
</acronym> year may be
10320 different from the Gregorian year. See the
<literal>week
</literal>
10321 field for more information.
10327 <term><literal>julian
</literal></term>
10330 The
<firstterm>Julian Date
</firstterm> corresponding to the
10331 date or timestamp. Timestamps
10332 that are not local midnight result in a fractional value. See
10333 <xref linkend=
"datetime-julian-dates"/> for more information.
10337 SELECT EXTRACT(JULIAN FROM DATE '
2006-
01-
01');
10338 <lineannotation>Result:
</lineannotation><computeroutput>2453737</computeroutput>
10339 SELECT EXTRACT(JULIAN FROM TIMESTAMP '
2006-
01-
01 12:
00');
10340 <lineannotation>Result:
</lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
10346 <term><literal>microseconds
</literal></term>
10349 The seconds field, including fractional parts, multiplied by
1
10350 000 000; note that this includes full seconds
10354 SELECT EXTRACT(MICROSECONDS FROM TIME '
17:
12:
28.5');
10355 <lineannotation>Result:
</lineannotation><computeroutput>28500000</computeroutput>
10361 <term><literal>millennium
</literal></term>
10364 The millennium; for
<type>interval
</type> values, the year field
10369 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10370 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10371 SELECT EXTRACT(MILLENNIUM FROM INTERVAL '
2001 years');
10372 <lineannotation>Result:
</lineannotation><computeroutput>2</computeroutput>
10376 Years in the
1900s are in the second millennium.
10377 The third millennium started January
1,
2001.
10383 <term><literal>milliseconds
</literal></term>
10386 The seconds field, including fractional parts, multiplied by
10387 1000. Note that this includes full seconds.
10391 SELECT EXTRACT(MILLISECONDS FROM TIME '
17:
12:
28.5');
10392 <lineannotation>Result:
</lineannotation><computeroutput>28500.000</computeroutput>
10398 <term><literal>minute
</literal></term>
10401 The minutes field (
0–59)
10405 SELECT EXTRACT(MINUTE FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10406 <lineannotation>Result:
</lineannotation><computeroutput>38</computeroutput>
10412 <term><literal>month
</literal></term>
10415 The number of the month within the year (
1–12);
10416 for
<type>interval
</type> values, the number of months modulo
12
10421 SELECT EXTRACT(MONTH FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10422 <lineannotation>Result:
</lineannotation><computeroutput>2</computeroutput>
10423 SELECT EXTRACT(MONTH FROM INTERVAL '
2 years
3 months');
10424 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10425 SELECT EXTRACT(MONTH FROM INTERVAL '
2 years
13 months');
10426 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10432 <term><literal>quarter
</literal></term>
10435 The quarter of the year (
1–4) that the date is in;
10436 for
<type>interval
</type> values, the month field divided by
3
10441 SELECT EXTRACT(QUARTER FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10442 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10443 SELECT EXTRACT(QUARTER FROM INTERVAL '
1 year
6 months');
10444 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10450 <term><literal>second
</literal></term>
10453 The seconds field, including any fractional seconds
10457 SELECT EXTRACT(SECOND FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10458 <lineannotation>Result:
</lineannotation><computeroutput>40.000000</computeroutput>
10459 SELECT EXTRACT(SECOND FROM TIME '
17:
12:
28.5');
10460 <lineannotation>Result:
</lineannotation><computeroutput>28.500000</computeroutput>
10465 <term><literal>timezone
</literal></term>
10468 The time zone offset from UTC, measured in seconds. Positive values
10469 correspond to time zones east of UTC, negative values to
10470 zones west of UTC. (Technically,
10471 <productname>PostgreSQL
</productname> does not use UTC because
10472 leap seconds are not handled.)
10478 <term><literal>timezone_hour
</literal></term>
10481 The hour component of the time zone offset
10487 <term><literal>timezone_minute
</literal></term>
10490 The minute component of the time zone offset
10496 <term><literal>week
</literal></term>
10499 The number of the
<acronym>ISO
</acronym> 8601 week-numbering week of
10500 the year. By definition, ISO weeks start on Mondays and the first
10501 week of a year contains January
4 of that year. In other words, the
10502 first Thursday of a year is in week
1 of that year.
10505 In the ISO week-numbering system, it is possible for early-January
10506 dates to be part of the
52nd or
53rd week of the previous year, and for
10507 late-December dates to be part of the first week of the next year.
10508 For example,
<literal>2005-
01-
01</literal> is part of the
53rd week of year
10509 2004, and
<literal>2006-
01-
01</literal> is part of the
52nd week of year
10510 2005, while
<literal>2012-
12-
31</literal> is part of the first week of
2013.
10511 It's recommended to use the
<literal>isoyear
</literal> field together with
10512 <literal>week
</literal> to get consistent results.
10516 For
<type>interval
</type> values, the week field is simply the number
10517 of integral days divided by
7.
10521 SELECT EXTRACT(WEEK FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10522 <lineannotation>Result:
</lineannotation><computeroutput>7</computeroutput>
10523 SELECT EXTRACT(WEEK FROM INTERVAL '
13 days
24 hours');
10524 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10530 <term><literal>year
</literal></term>
10533 The year field. Keep in mind there is no
<literal>0 AD
</literal>, so subtracting
10534 <literal>BC
</literal> years from
<literal>AD
</literal> years should be done with care.
10538 SELECT EXTRACT(YEAR FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10539 <lineannotation>Result:
</lineannotation><computeroutput>2001</computeroutput>
10548 When processing an
<type>interval
</type> value,
10549 the
<function>extract
</function> function produces field values that
10550 match the interpretation used by the interval output function. This
10551 can produce surprising results if one starts with a non-normalized
10552 interval representation, for example:
10554 SELECT INTERVAL '
80 minutes';
10555 <lineannotation>Result:
</lineannotation><computeroutput>01:
20:
00</computeroutput>
10556 SELECT EXTRACT(MINUTES FROM INTERVAL '
80 minutes');
10557 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10563 When the input value is +/-Infinity,
<function>extract
</function> returns
10564 +/-Infinity for monotonically-increasing fields (
<literal>epoch
</literal>,
10565 <literal>julian
</literal>,
<literal>year
</literal>,
<literal>isoyear
</literal>,
10566 <literal>decade
</literal>,
<literal>century
</literal>, and
<literal>millennium
</literal>
10567 for
<type>timestamp
</type> inputs;
<literal>epoch
</literal>,
<literal>hour
</literal>,
10568 <literal>day
</literal>,
<literal>year
</literal>,
<literal>decade
</literal>,
10569 <literal>century
</literal>, and
<literal>millennium
</literal> for
10570 <type>interval
</type> inputs).
10571 For other fields, NULL is returned.
<productname>PostgreSQL
</productname>
10572 versions before
9.6 returned zero for all cases of infinite input.
10577 The
<function>extract
</function> function is primarily intended
10578 for computational processing. For formatting date/time values for
10579 display, see
<xref linkend=
"functions-formatting"/>.
10583 The
<function>date_part
</function> function is modeled on the traditional
10584 <productname>Ingres
</productname> equivalent to the
10585 <acronym>SQL
</acronym>-standard function
<function>extract
</function>:
10587 date_part('
<replaceable>field
</replaceable>',
<replaceable>source
</replaceable>)
10589 Note that here the
<replaceable>field
</replaceable> parameter needs to
10590 be a string value, not a name. The valid field names for
10591 <function>date_part
</function> are the same as for
10592 <function>extract
</function>.
10593 For historical reasons, the
<function>date_part
</function> function
10594 returns values of type
<type>double precision
</type>. This can result in
10595 a loss of precision in certain uses. Using
<function>extract
</function>
10596 is recommended instead.
10600 SELECT date_part('day', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10601 <lineannotation>Result:
</lineannotation><computeroutput>16</computeroutput>
10602 SELECT date_part('hour', INTERVAL '
4 hours
3 minutes');
10603 <lineannotation>Result:
</lineannotation><computeroutput>4</computeroutput>
10608 <sect2 id=
"functions-datetime-trunc">
10609 <title><function>date_trunc
</function></title>
10612 <primary>date_trunc
</primary>
10616 The function
<function>date_trunc
</function> is conceptually
10617 similar to the
<function>trunc
</function> function for numbers.
10622 date_trunc(
<replaceable>field
</replaceable>,
<replaceable>source
</replaceable> [,
<replaceable>time_zone
</replaceable> ])
10624 <replaceable>source
</replaceable> is a value expression of type
10625 <type>timestamp
</type>,
<type>timestamp with time zone
</type>,
10626 or
<type>interval
</type>.
10627 (Values of type
<type>date
</type> and
10628 <type>time
</type> are cast automatically to
<type>timestamp
</type> or
10629 <type>interval
</type>, respectively.)
10630 <replaceable>field
</replaceable> selects to which precision to
10631 truncate the input value. The return value is likewise of type
10632 <type>timestamp
</type>,
<type>timestamp with time zone
</type>,
10633 or
<type>interval
</type>,
10634 and it has all fields that are less significant than the
10635 selected one set to zero (or one, for day and month).
10639 Valid values for
<replaceable>field
</replaceable> are:
10641 <member><literal>microseconds
</literal></member>
10642 <member><literal>milliseconds
</literal></member>
10643 <member><literal>second
</literal></member>
10644 <member><literal>minute
</literal></member>
10645 <member><literal>hour
</literal></member>
10646 <member><literal>day
</literal></member>
10647 <member><literal>week
</literal></member>
10648 <member><literal>month
</literal></member>
10649 <member><literal>quarter
</literal></member>
10650 <member><literal>year
</literal></member>
10651 <member><literal>decade
</literal></member>
10652 <member><literal>century
</literal></member>
10653 <member><literal>millennium
</literal></member>
10658 When the input value is of type
<type>timestamp with time zone
</type>,
10659 the truncation is performed with respect to a particular time zone;
10660 for example, truncation to
<literal>day
</literal> produces a value that
10661 is midnight in that zone. By default, truncation is done with respect
10662 to the current
<xref linkend=
"guc-timezone"/> setting, but the
10663 optional
<replaceable>time_zone
</replaceable> argument can be provided
10664 to specify a different time zone. The time zone name can be specified
10665 in any of the ways described in
<xref linkend=
"datatype-timezones"/>.
10669 A time zone cannot be specified when processing
<type>timestamp without
10670 time zone
</type> or
<type>interval
</type> inputs. These are always
10671 taken at face value.
10675 Examples (assuming the local time zone is
<literal>America/New_York
</literal>):
10677 SELECT date_trunc('hour', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10678 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 20:
00:
00</computeroutput>
10679 SELECT date_trunc('year', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10680 <lineannotation>Result:
</lineannotation><computeroutput>2001-
01-
01 00:
00:
00</computeroutput>
10681 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40+
00');
10682 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 00:
00:
00-
05</computeroutput>
10683 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40+
00', 'Australia/Sydney');
10684 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 08:
00:
00-
05</computeroutput>
10685 SELECT date_trunc('hour', INTERVAL '
3 days
02:
47:
33');
10686 <lineannotation>Result:
</lineannotation><computeroutput>3 days
02:
00:
00</computeroutput>
10691 <sect2 id=
"functions-datetime-bin">
10692 <title><function>date_bin
</function></title>
10695 <primary>date_bin
</primary>
10699 The function
<function>date_bin
</function> <quote>bins
</quote> the input
10700 timestamp into the specified interval (the
<firstterm>stride
</firstterm>)
10701 aligned with a specified origin.
10706 date_bin(
<replaceable>stride
</replaceable>,
<replaceable>source
</replaceable>,
<replaceable>origin
</replaceable>)
10708 <replaceable>source
</replaceable> is a value expression of type
10709 <type>timestamp
</type> or
<type>timestamp with time zone
</type>. (Values
10710 of type
<type>date
</type> are cast automatically to
10711 <type>timestamp
</type>.)
<replaceable>stride
</replaceable> is a value
10712 expression of type
<type>interval
</type>. The return value is likewise
10713 of type
<type>timestamp
</type> or
<type>timestamp with time zone
</type>,
10714 and it marks the beginning of the bin into which the
10715 <replaceable>source
</replaceable> is placed.
10721 SELECT date_bin('
15 minutes', TIMESTAMP '
2020-
02-
11 15:
44:
17', TIMESTAMP '
2001-
01-
01');
10722 <lineannotation>Result:
</lineannotation><computeroutput>2020-
02-
11 15:
30:
00</computeroutput>
10723 SELECT date_bin('
15 minutes', TIMESTAMP '
2020-
02-
11 15:
44:
17', TIMESTAMP '
2001-
01-
01 00:
02:
30');
10724 <lineannotation>Result:
</lineannotation><computeroutput>2020-
02-
11 15:
32:
30</computeroutput>
10729 In the case of full units (
1 minute,
1 hour, etc.), it gives the same result as
10730 the analogous
<function>date_trunc
</function> call, but the difference is
10731 that
<function>date_bin
</function> can truncate to an arbitrary interval.
10735 The
<parameter>stride
</parameter> interval must be greater than zero and
10736 cannot contain units of month or larger.
10740 <sect2 id=
"functions-datetime-zoneconvert">
10741 <title><literal>AT TIME ZONE and AT LOCAL
</literal></title>
10744 <primary>time zone
</primary>
10745 <secondary>conversion
</secondary>
10749 <primary>AT TIME ZONE
</primary>
10753 <primary>AT LOCAL
</primary>
10757 The
<literal>AT TIME ZONE
</literal> operator converts time
10758 stamp
<emphasis>without
</emphasis> time zone to/from
10759 time stamp
<emphasis>with
</emphasis> time zone, and
10760 <type>time with time zone
</type> values to different time
10761 zones.
<xref linkend=
"functions-datetime-zoneconvert-table"/> shows its
10765 <table id=
"functions-datetime-zoneconvert-table">
10766 <title><literal>AT TIME ZONE
</literal> and
<literal>AT LOCAL
</literal> Variants
</title>
10770 <entry role=
"func_table_entry"><para role=
"func_signature">
10784 <entry role=
"func_table_entry"><para role=
"func_signature">
10785 <type>timestamp without time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10786 <returnvalue>timestamp with time zone
</returnvalue>
10789 Converts given time stamp
<emphasis>without
</emphasis> time zone to
10790 time stamp
<emphasis>with
</emphasis> time zone, assuming the given
10791 value is in the named time zone.
10794 <literal>timestamp '
2001-
02-
16 20:
38:
40' at time zone 'America/Denver'
</literal>
10795 <returnvalue>2001-
02-
17 03:
38:
40+
00</returnvalue>
10800 <entry role=
"func_table_entry"><para role=
"func_signature">
10801 <type>timestamp without time zone
</type> <literal>AT LOCAL
</literal>
10802 <returnvalue>timestamp with time zone
</returnvalue>
10805 Converts given time stamp
<emphasis>without
</emphasis> time zone to
10806 time stamp
<emphasis>with
</emphasis> the session's
10807 <varname>TimeZone
</varname> value as time zone.
10810 <literal>timestamp '
2001-
02-
16 20:
38:
40' at local
</literal>
10811 <returnvalue>2001-
02-
17 03:
38:
40+
00</returnvalue>
10816 <entry role=
"func_table_entry"><para role=
"func_signature">
10817 <type>timestamp with time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10818 <returnvalue>timestamp without time zone
</returnvalue>
10821 Converts given time stamp
<emphasis>with
</emphasis> time zone to
10822 time stamp
<emphasis>without
</emphasis> time zone, as the time would
10823 appear in that zone.
10826 <literal>timestamp with time zone '
2001-
02-
16 20:
38:
40-
05' at time zone 'America/Denver'
</literal>
10827 <returnvalue>2001-
02-
16 18:
38:
40</returnvalue>
10832 <entry role=
"func_table_entry"><para role=
"func_signature">
10833 <type>timestamp with time zone
</type> <literal>AT LOCAL
</literal>
10834 <returnvalue>timestamp without time zone
</returnvalue>
10837 Converts given time stamp
<emphasis>with
</emphasis> time zone to
10838 time stamp
<emphasis>without
</emphasis> time zone, as the time would
10839 appear with the session's
<varname>TimeZone
</varname> value as time zone.
10842 <literal>timestamp with time zone '
2001-
02-
16 20:
38:
40-
05' at local
</literal>
10843 <returnvalue>2001-
02-
16 18:
38:
40</returnvalue>
10848 <entry role=
"func_table_entry"><para role=
"func_signature">
10849 <type>time with time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10850 <returnvalue>time with time zone
</returnvalue>
10853 Converts given time
<emphasis>with
</emphasis> time zone to a new time
10854 zone. Since no date is supplied, this uses the currently active UTC
10855 offset for the named destination zone.
10858 <literal>time with time zone '
05:
34:
17-
05' at time zone 'UTC'
</literal>
10859 <returnvalue>10:
34:
17+
00</returnvalue>
10864 <entry role=
"func_table_entry"><para role=
"func_signature">
10865 <type>time with time zone
</type> <literal>AT LOCAL
</literal>
10866 <returnvalue>time with time zone
</returnvalue>
10869 Converts given time
<emphasis>with
</emphasis> time zone to a new time
10870 zone. Since no date is supplied, this uses the currently active UTC
10871 offset for the session's
<varname>TimeZone
</varname> value.
10874 Assuming the session's
<varname>TimeZone
</varname> is set to
<literal>UTC
</literal>:
10877 <literal>time with time zone '
05:
34:
17-
05' at local
</literal>
10878 <returnvalue>10:
34:
17+
00</returnvalue>
10886 In these expressions, the desired time zone
<replaceable>zone
</replaceable> can be
10887 specified either as a text value (e.g.,
<literal>'America/Los_Angeles'
</literal>)
10888 or as an interval (e.g.,
<literal>INTERVAL '-
08:
00'
</literal>).
10889 In the text case, a time zone name can be specified in any of the ways
10890 described in
<xref linkend=
"datatype-timezones"/>.
10891 The interval case is only useful for zones that have fixed offsets from
10892 UTC, so it is not very common in practice.
10896 The syntax
<literal>AT LOCAL
</literal> may be used as shorthand for
10897 <literal>AT TIME ZONE
<replaceable>local
</replaceable></literal>, where
10898 <replaceable>local
</replaceable> is the session's
10899 <varname>TimeZone
</varname> value.
10903 Examples (assuming the current
<xref linkend=
"guc-timezone"/> setting
10904 is
<literal>America/Los_Angeles
</literal>):
10906 SELECT TIMESTAMP '
2001-
02-
16 20:
38:
40' AT TIME ZONE 'America/Denver';
10907 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 19:
38:
40-
08</computeroutput>
10908 SELECT TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40-
05' AT TIME ZONE 'America/Denver';
10909 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 18:
38:
40</computeroutput>
10910 SELECT TIMESTAMP '
2001-
02-
16 20:
38:
40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
10911 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 05:
38:
40</computeroutput>
10912 SELECT TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40-
05' AT LOCAL;
10913 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 17:
38:
40</computeroutput>
10914 SELECT TIME WITH TIME ZONE '
20:
38:
40-
05' AT LOCAL;
10915 <lineannotation>Result:
</lineannotation><computeroutput>17:
38:
40</computeroutput>
10917 The first example adds a time zone to a value that lacks it, and
10918 displays the value using the current
<varname>TimeZone
</varname>
10919 setting. The second example shifts the time stamp with time zone value
10920 to the specified time zone, and returns the value without a time zone.
10921 This allows storage and display of values different from the current
10922 <varname>TimeZone
</varname> setting. The third example converts
10923 Tokyo time to Chicago time. The fourth example shifts the time stamp
10924 with time zone value to the time zone currently specified by the
10925 <varname>TimeZone
</varname> setting and returns the value without a
10930 The fifth example is a cautionary tale. Due to the fact that there is no
10931 date associated with the input value, the conversion is made using the
10932 current date of the session. Therefore, this static example may show a wrong
10933 result depending on the time of the year it is viewed because
10934 <literal>'America/Los_Angeles'
</literal> observes Daylight Savings Time.
10938 The function
<literal><function>timezone
</function>(
<replaceable>zone
</replaceable>,
10939 <replaceable>timestamp
</replaceable>)
</literal> is equivalent to the SQL-conforming construct
10940 <literal><replaceable>timestamp
</replaceable> AT TIME ZONE
10941 <replaceable>zone
</replaceable></literal>.
10945 The function
<literal><function>timezone
</function>(
<replaceable>zone
</replaceable>,
10946 <replaceable>time
</replaceable>)
</literal> is equivalent to the SQL-conforming construct
10947 <literal><replaceable>time
</replaceable> AT TIME ZONE
10948 <replaceable>zone
</replaceable></literal>.
10952 The function
<literal><function>timezone
</function>(
<replaceable>timestamp
</replaceable>)
</literal>
10953 is equivalent to the SQL-conforming construct
<literal><replaceable>timestamp
</replaceable>
10954 AT LOCAL
</literal>.
10958 The function
<literal><function>timezone
</function>(
<replaceable>time
</replaceable>)
</literal>
10959 is equivalent to the SQL-conforming construct
<literal><replaceable>time
</replaceable>
10960 AT LOCAL
</literal>.
10964 <sect2 id=
"functions-datetime-current">
10965 <title>Current Date/Time
</title>
10968 <primary>date
</primary>
10969 <secondary>current
</secondary>
10973 <primary>time
</primary>
10974 <secondary>current
</secondary>
10978 <productname>PostgreSQL
</productname> provides a number of functions
10979 that return values related to the current date and time. These
10980 SQL-standard functions all return values based on the start time of
10981 the current transaction:
10986 CURRENT_TIME(
<replaceable>precision
</replaceable>)
10987 CURRENT_TIMESTAMP(
<replaceable>precision
</replaceable>)
10990 LOCALTIME(
<replaceable>precision
</replaceable>)
10991 LOCALTIMESTAMP(
<replaceable>precision
</replaceable>)
10996 <function>CURRENT_TIME
</function> and
10997 <function>CURRENT_TIMESTAMP
</function> deliver values with time zone;
10998 <function>LOCALTIME
</function> and
10999 <function>LOCALTIMESTAMP
</function> deliver values without time zone.
11003 <function>CURRENT_TIME
</function>,
11004 <function>CURRENT_TIMESTAMP
</function>,
11005 <function>LOCALTIME
</function>, and
11006 <function>LOCALTIMESTAMP
</function>
11007 can optionally take
11008 a precision parameter, which causes the result to be rounded
11009 to that many fractional digits in the seconds field. Without a precision parameter,
11010 the result is given to the full available precision.
11016 SELECT CURRENT_TIME;
11017 <lineannotation>Result:
</lineannotation><computeroutput>14:
39:
53.662522-
05</computeroutput>
11018 SELECT CURRENT_DATE;
11019 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23</computeroutput>
11020 SELECT CURRENT_TIMESTAMP;
11021 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.662522-
05</computeroutput>
11022 SELECT CURRENT_TIMESTAMP(
2);
11023 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.66-
05</computeroutput>
11024 SELECT LOCALTIMESTAMP;
11025 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.662522</computeroutput>
11030 Since these functions return
11031 the start time of the current transaction, their values do not
11032 change during the transaction. This is considered a feature:
11033 the intent is to allow a single transaction to have a consistent
11034 notion of the
<quote>current
</quote> time, so that multiple
11035 modifications within the same transaction bear the same
11041 Other database systems might advance these values more
11047 <productname>PostgreSQL
</productname> also provides functions that
11048 return the start time of the current statement, as well as the actual
11049 current time at the instant the function is called. The complete list
11050 of non-SQL-standard time functions is:
11052 transaction_timestamp()
11053 statement_timestamp()
11061 <function>transaction_timestamp()
</function> is equivalent to
11062 <function>CURRENT_TIMESTAMP
</function>, but is named to clearly reflect
11064 <function>statement_timestamp()
</function> returns the start time of the current
11065 statement (more specifically, the time of receipt of the latest command
11066 message from the client).
11067 <function>statement_timestamp()
</function> and
<function>transaction_timestamp()
</function>
11068 return the same value during the first command of a transaction, but might
11069 differ during subsequent commands.
11070 <function>clock_timestamp()
</function> returns the actual current time, and
11071 therefore its value changes even within a single SQL command.
11072 <function>timeofday()
</function> is a historical
11073 <productname>PostgreSQL
</productname> function. Like
11074 <function>clock_timestamp()
</function>, it returns the actual current time,
11075 but as a formatted
<type>text
</type> string rather than a
<type>timestamp
11076 with time zone
</type> value.
11077 <function>now()
</function> is a traditional
<productname>PostgreSQL
</productname>
11078 equivalent to
<function>transaction_timestamp()
</function>.
11082 All the date/time data types also accept the special literal value
11083 <literal>now
</literal> to specify the current date and time (again,
11084 interpreted as the transaction start time). Thus,
11085 the following three all return the same result:
11087 SELECT CURRENT_TIMESTAMP;
11089 SELECT TIMESTAMP 'now'; -- but see tip below
11095 Do not use the third form when specifying a value to be evaluated later,
11096 for example in a
<literal>DEFAULT
</literal> clause for a table column.
11097 The system will convert
<literal>now
</literal>
11098 to a
<type>timestamp
</type> as soon as the constant is parsed, so that when
11099 the default value is needed,
11100 the time of the table creation would be used! The first two
11101 forms will not be evaluated until the default value is used,
11102 because they are function calls. Thus they will give the desired
11103 behavior of defaulting to the time of row insertion.
11104 (See also
<xref linkend=
"datatype-datetime-special-values"/>.)
11109 <sect2 id=
"functions-datetime-delay">
11110 <title>Delaying Execution
</title>
11113 <primary>pg_sleep
</primary>
11116 <primary>pg_sleep_for
</primary>
11119 <primary>pg_sleep_until
</primary>
11122 <primary>sleep
</primary>
11125 <primary>delay
</primary>
11129 The following functions are available to delay execution of the server
11132 pg_sleep (
<type>double precision
</type> )
11133 pg_sleep_for (
<type>interval
</type> )
11134 pg_sleep_until (
<type>timestamp with time zone
</type> )
11137 <function>pg_sleep
</function> makes the current session's process
11138 sleep until the given number of seconds have
11139 elapsed. Fractional-second delays can be specified.
11140 <function>pg_sleep_for
</function> is a convenience function to
11141 allow the sleep time to be specified as an
<type>interval
</type>.
11142 <function>pg_sleep_until
</function> is a convenience function for when
11143 a specific wake-up time is desired.
11147 SELECT pg_sleep(
1.5);
11148 SELECT pg_sleep_for('
5 minutes');
11149 SELECT pg_sleep_until('tomorrow
03:
00');
11155 The effective resolution of the sleep interval is platform-specific;
11156 0.01 seconds is a common value. The sleep delay will be at least as long
11157 as specified. It might be longer depending on factors such as server load.
11158 In particular,
<function>pg_sleep_until
</function> is not guaranteed to
11159 wake up exactly at the specified time, but it will not wake up any earlier.
11165 Make sure that your session does not hold more locks than necessary
11166 when calling
<function>pg_sleep
</function> or its variants. Otherwise
11167 other sessions might have to wait for your sleeping process, slowing down
11176 <sect1 id=
"functions-enum">
11177 <title>Enum Support Functions
</title>
11180 For enum types (described in
<xref linkend=
"datatype-enum"/>),
11181 there are several functions that allow cleaner programming without
11182 hard-coding particular values of an enum type.
11183 These are listed in
<xref linkend=
"functions-enum-table"/>. The examples
11184 assume an enum type created as:
11187 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
11192 <table id=
"functions-enum-table">
11193 <title>Enum Support Functions
</title>
11197 <entry role=
"func_table_entry"><para role=
"func_signature">
11211 <entry role=
"func_table_entry"><para role=
"func_signature">
11213 <primary>enum_first
</primary>
11215 <function>enum_first
</function> (
<type>anyenum
</type> )
11216 <returnvalue>anyenum
</returnvalue>
11219 Returns the first value of the input enum type.
11222 <literal>enum_first(null::rainbow)
</literal>
11223 <returnvalue>red
</returnvalue>
11227 <entry role=
"func_table_entry"><para role=
"func_signature">
11229 <primary>enum_last
</primary>
11231 <function>enum_last
</function> (
<type>anyenum
</type> )
11232 <returnvalue>anyenum
</returnvalue>
11235 Returns the last value of the input enum type.
11238 <literal>enum_last(null::rainbow)
</literal>
11239 <returnvalue>purple
</returnvalue>
11243 <entry role=
"func_table_entry"><para role=
"func_signature">
11245 <primary>enum_range
</primary>
11247 <function>enum_range
</function> (
<type>anyenum
</type> )
11248 <returnvalue>anyarray
</returnvalue>
11251 Returns all values of the input enum type in an ordered array.
11254 <literal>enum_range(null::rainbow)
</literal>
11255 <returnvalue>{red,orange,yellow,
&zwsp;green,blue,purple}
</returnvalue>
11259 <entry role=
"func_table_entry"><para role=
"func_signature">
11260 <function>enum_range
</function> (
<type>anyenum
</type>,
<type>anyenum
</type> )
11261 <returnvalue>anyarray
</returnvalue>
11264 Returns the range between the two given enum values, as an ordered
11265 array. The values must be from the same enum type. If the first
11266 parameter is null, the result will start with the first value of
11268 If the second parameter is null, the result will end with the last
11269 value of the enum type.
11272 <literal>enum_range('orange'::rainbow, 'green'::rainbow)
</literal>
11273 <returnvalue>{orange,yellow,green}
</returnvalue>
11276 <literal>enum_range(NULL, 'green'::rainbow)
</literal>
11277 <returnvalue>{red,orange,
&zwsp;yellow,green}
</returnvalue>
11280 <literal>enum_range('orange'::rainbow, NULL)
</literal>
11281 <returnvalue>{orange,yellow,green,
&zwsp;blue,purple}
</returnvalue>
11289 Notice that except for the two-argument form of
<function>enum_range
</function>,
11290 these functions disregard the specific value passed to them; they care
11291 only about its declared data type. Either null or a specific value of
11292 the type can be passed, with the same result. It is more common to
11293 apply these functions to a table column or function argument than to
11294 a hardwired type name as used in the examples.
11298 <sect1 id=
"functions-geometry">
11299 <title>Geometric Functions and Operators
</title>
11302 The geometric types
<type>point
</type>,
<type>box
</type>,
11303 <type>lseg
</type>,
<type>line
</type>,
<type>path
</type>,
11304 <type>polygon
</type>, and
<type>circle
</type> have a large set of
11305 native support functions and operators, shown in
<xref
11306 linkend=
"functions-geometry-op-table"/>,
<xref
11307 linkend=
"functions-geometry-func-table"/>, and
<xref
11308 linkend=
"functions-geometry-conv-table"/>.
11311 <table id=
"functions-geometry-op-table">
11312 <title>Geometric Operators
</title>
11316 <entry role=
"func_table_entry"><para role=
"func_signature">
11330 <entry role=
"func_table_entry"><para role=
"func_signature">
11331 <replaceable>geometric_type
</replaceable> <literal>+
</literal> <type>point
</type>
11332 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11335 Adds the coordinates of the second
<type>point
</type> to those of each
11336 point of the first argument, thus performing translation.
11337 Available for
<type>point
</type>,
<type>box
</type>,
<type>path
</type>,
11338 <type>circle
</type>.
11341 <literal>box '(
1,
1),(
0,
0)' + point '(
2,
0)'
</literal>
11342 <returnvalue>(
3,
1),(
2,
0)
</returnvalue>
11347 <entry role=
"func_table_entry"><para role=
"func_signature">
11348 <type>path
</type> <literal>+
</literal> <type>path
</type>
11349 <returnvalue>path
</returnvalue>
11352 Concatenates two open paths (returns NULL if either path is closed).
11355 <literal>path '[(
0,
0),(
1,
1)]' + path '[(
2,
2),(
3,
3),(
4,
4)]'
</literal>
11356 <returnvalue>[(
0,
0),(
1,
1),(
2,
2),(
3,
3),(
4,
4)]
</returnvalue>
11361 <entry role=
"func_table_entry"><para role=
"func_signature">
11362 <replaceable>geometric_type
</replaceable> <literal>-
</literal> <type>point
</type>
11363 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11366 Subtracts the coordinates of the second
<type>point
</type> from those
11367 of each point of the first argument, thus performing translation.
11368 Available for
<type>point
</type>,
<type>box
</type>,
<type>path
</type>,
11369 <type>circle
</type>.
11372 <literal>box '(
1,
1),(
0,
0)' - point '(
2,
0)'
</literal>
11373 <returnvalue>(-
1,
1),(-
2,
0)
</returnvalue>
11378 <entry role=
"func_table_entry"><para role=
"func_signature">
11379 <replaceable>geometric_type
</replaceable> <literal>*
</literal> <type>point
</type>
11380 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11383 Multiplies each point of the first argument by the second
11384 <type>point
</type> (treating a point as being a complex number
11385 represented by real and imaginary parts, and performing standard
11386 complex multiplication). If one interprets
11387 the second
<type>point
</type> as a vector, this is equivalent to
11388 scaling the object's size and distance from the origin by the length
11389 of the vector, and rotating it counterclockwise around the origin by
11390 the vector's angle from the
<replaceable>x
</replaceable> axis.
11391 Available for
<type>point
</type>,
<type>box
</type>,
<footnote
11392 id=
"functions-geometry-rotation-fn"><para><quote>Rotating
</quote> a
11393 box with these operators only moves its corner points: the box is
11394 still considered to have sides parallel to the axes. Hence the box's
11395 size is not preserved, as a true rotation would do.
</para></footnote>
11396 <type>path
</type>,
<type>circle
</type>.
11399 <literal>path '((
0,
0),(
1,
0),(
1,
1))' * point '(
3.0,
0)'
</literal>
11400 <returnvalue>((
0,
0),(
3,
0),(
3,
3))
</returnvalue>
11403 <literal>path '((
0,
0),(
1,
0),(
1,
1))' * point(cosd(
45), sind(
45))
</literal>
11404 <returnvalue>((
0,
0),
&zwsp;(
0.7071067811865475,
0.7071067811865475),
&zwsp;(
0,
1.414213562373095))
</returnvalue>
11409 <entry role=
"func_table_entry"><para role=
"func_signature">
11410 <replaceable>geometric_type
</replaceable> <literal>/
</literal> <type>point
</type>
11411 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11414 Divides each point of the first argument by the second
11415 <type>point
</type> (treating a point as being a complex number
11416 represented by real and imaginary parts, and performing standard
11417 complex division). If one interprets
11418 the second
<type>point
</type> as a vector, this is equivalent to
11419 scaling the object's size and distance from the origin down by the
11420 length of the vector, and rotating it clockwise around the origin by
11421 the vector's angle from the
<replaceable>x
</replaceable> axis.
11422 Available for
<type>point
</type>,
<type>box
</type>,
<footnoteref
11423 linkend=
"functions-geometry-rotation-fn"/> <type>path
</type>,
11424 <type>circle
</type>.
11427 <literal>path '((
0,
0),(
1,
0),(
1,
1))' / point '(
2.0,
0)'
</literal>
11428 <returnvalue>((
0,
0),(
0.5,
0),(
0.5,
0.5))
</returnvalue>
11431 <literal>path '((
0,
0),(
1,
0),(
1,
1))' / point(cosd(
45), sind(
45))
</literal>
11432 <returnvalue>((
0,
0),
&zwsp;(
0.7071067811865476,-
0.7071067811865476),
&zwsp;(
1.4142135623730951,
0))
</returnvalue>
11437 <entry role=
"func_table_entry"><para role=
"func_signature">
11438 <literal>@-@
</literal> <replaceable>geometric_type
</replaceable>
11439 <returnvalue>double precision
</returnvalue>
11442 Computes the total length.
11443 Available for
<type>lseg
</type>,
<type>path
</type>.
11446 <literal>@-@ path '[(
0,
0),(
1,
0),(
1,
1)]'
</literal>
11447 <returnvalue>2</returnvalue>
11452 <entry role=
"func_table_entry"><para role=
"func_signature">
11453 <literal>@@
</literal> <replaceable>geometric_type
</replaceable>
11454 <returnvalue>point
</returnvalue>
11457 Computes the center point.
11458 Available for
<type>box
</type>,
<type>lseg
</type>,
11459 <type>polygon
</type>,
<type>circle
</type>.
11462 <literal>@@ box '(
2,
2),(
0,
0)'
</literal>
11463 <returnvalue>(
1,
1)
</returnvalue>
11468 <entry role=
"func_table_entry"><para role=
"func_signature">
11469 <literal>#
</literal> <replaceable>geometric_type
</replaceable>
11470 <returnvalue>integer
</returnvalue>
11473 Returns the number of points.
11474 Available for
<type>path
</type>,
<type>polygon
</type>.
11477 <literal># path '((
1,
0),(
0,
1),(-
1,
0))'
</literal>
11478 <returnvalue>3</returnvalue>
11483 <entry role=
"func_table_entry"><para role=
"func_signature">
11484 <replaceable>geometric_type
</replaceable> <literal>#
</literal> <replaceable>geometric_type
</replaceable>
11485 <returnvalue>point
</returnvalue>
11488 Computes the point of intersection, or NULL if there is none.
11489 Available for
<type>lseg
</type>,
<type>line
</type>.
11492 <literal>lseg '[(
0,
0),(
1,
1)]' # lseg '[(
1,
0),(
0,
1)]'
</literal>
11493 <returnvalue>(
0.5,
0.5)
</returnvalue>
11498 <entry role=
"func_table_entry"><para role=
"func_signature">
11499 <type>box
</type> <literal>#
</literal> <type>box
</type>
11500 <returnvalue>box
</returnvalue>
11503 Computes the intersection of two boxes, or NULL if there is none.
11506 <literal>box '(
2,
2),(-
1,-
1)' # box '(
1,
1),(-
2,-
2)'
</literal>
11507 <returnvalue>(
1,
1),(-
1,-
1)
</returnvalue>
11512 <entry role=
"func_table_entry"><para role=
"func_signature">
11513 <replaceable>geometric_type
</replaceable> <literal>##
</literal> <replaceable>geometric_type
</replaceable>
11514 <returnvalue>point
</returnvalue>
11517 Computes the closest point to the first object on the second object.
11518 Available for these pairs of types:
11519 (
<type>point
</type>,
<type>box
</type>),
11520 (
<type>point
</type>,
<type>lseg
</type>),
11521 (
<type>point
</type>,
<type>line
</type>),
11522 (
<type>lseg
</type>,
<type>box
</type>),
11523 (
<type>lseg
</type>,
<type>lseg
</type>),
11524 (
<type>line
</type>,
<type>lseg
</type>).
11527 <literal>point '(
0,
0)' ## lseg '[(
2,
0),(
0,
2)]'
</literal>
11528 <returnvalue>(
1,
1)
</returnvalue>
11533 <entry role=
"func_table_entry"><para role=
"func_signature">
11534 <replaceable>geometric_type
</replaceable> <literal><-
></literal> <replaceable>geometric_type
</replaceable>
11535 <returnvalue>double precision
</returnvalue>
11538 Computes the distance between the objects.
11539 Available for all seven geometric types, for all combinations
11540 of
<type>point
</type> with another geometric type, and for
11541 these additional pairs of types:
11542 (
<type>box
</type>,
<type>lseg
</type>),
11543 (
<type>lseg
</type>,
<type>line
</type>),
11544 (
<type>polygon
</type>,
<type>circle
</type>)
11545 (and the commutator cases).
11548 <literal>circle '
<(
0,
0),
1>'
<-
> circle '
<(
5,
0),
1>'
</literal>
11549 <returnvalue>3</returnvalue>
11554 <entry role=
"func_table_entry"><para role=
"func_signature">
11555 <replaceable>geometric_type
</replaceable> <literal>@
></literal> <replaceable>geometric_type
</replaceable>
11556 <returnvalue>boolean
</returnvalue>
11559 Does first object contain second?
11560 Available for these pairs of types:
11561 (
<literal>box
</literal>,
<literal>point
</literal>),
11562 (
<literal>box
</literal>,
<literal>box
</literal>),
11563 (
<literal>path
</literal>,
<literal>point
</literal>),
11564 (
<literal>polygon
</literal>,
<literal>point
</literal>),
11565 (
<literal>polygon
</literal>,
<literal>polygon
</literal>),
11566 (
<literal>circle
</literal>,
<literal>point
</literal>),
11567 (
<literal>circle
</literal>,
<literal>circle
</literal>).
11570 <literal>circle '
<(
0,
0),
2>' @
> point '(
1,
1)'
</literal>
11571 <returnvalue>t
</returnvalue>
11576 <entry role=
"func_table_entry"><para role=
"func_signature">
11577 <replaceable>geometric_type
</replaceable> <literal><@
</literal> <replaceable>geometric_type
</replaceable>
11578 <returnvalue>boolean
</returnvalue>
11581 Is first object contained in or on second?
11582 Available for these pairs of types:
11583 (
<literal>point
</literal>,
<literal>box
</literal>),
11584 (
<literal>point
</literal>,
<literal>lseg
</literal>),
11585 (
<literal>point
</literal>,
<literal>line
</literal>),
11586 (
<literal>point
</literal>,
<literal>path
</literal>),
11587 (
<literal>point
</literal>,
<literal>polygon
</literal>),
11588 (
<literal>point
</literal>,
<literal>circle
</literal>),
11589 (
<literal>box
</literal>,
<literal>box
</literal>),
11590 (
<literal>lseg
</literal>,
<literal>box
</literal>),
11591 (
<literal>lseg
</literal>,
<literal>line
</literal>),
11592 (
<literal>polygon
</literal>,
<literal>polygon
</literal>),
11593 (
<literal>circle
</literal>,
<literal>circle
</literal>).
11596 <literal>point '(
1,
1)'
<@ circle '
<(
0,
0),
2>'
</literal>
11597 <returnvalue>t
</returnvalue>
11602 <entry role=
"func_table_entry"><para role=
"func_signature">
11603 <replaceable>geometric_type
</replaceable> <literal>&&</literal> <replaceable>geometric_type
</replaceable>
11604 <returnvalue>boolean
</returnvalue>
11607 Do these objects overlap? (One point in common makes this true.)
11608 Available for
<type>box
</type>,
<type>polygon
</type>,
11609 <type>circle
</type>.
11612 <literal>box '(
1,
1),(
0,
0)'
&& box '(
2,
2),(
0,
0)'
</literal>
11613 <returnvalue>t
</returnvalue>
11618 <entry role=
"func_table_entry"><para role=
"func_signature">
11619 <replaceable>geometric_type
</replaceable> <literal><<</literal> <replaceable>geometric_type
</replaceable>
11620 <returnvalue>boolean
</returnvalue>
11623 Is first object strictly left of second?
11624 Available for
<type>point
</type>,
<type>box
</type>,
11625 <type>polygon
</type>,
<type>circle
</type>.
11628 <literal>circle '
<(
0,
0),
1>'
<< circle '
<(
5,
0),
1>'
</literal>
11629 <returnvalue>t
</returnvalue>
11634 <entry role=
"func_table_entry"><para role=
"func_signature">
11635 <replaceable>geometric_type
</replaceable> <literal>>></literal> <replaceable>geometric_type
</replaceable>
11636 <returnvalue>boolean
</returnvalue>
11639 Is first object strictly right of second?
11640 Available for
<type>point
</type>,
<type>box
</type>,
11641 <type>polygon
</type>,
<type>circle
</type>.
11644 <literal>circle '
<(
5,
0),
1>'
>> circle '
<(
0,
0),
1>'
</literal>
11645 <returnvalue>t
</returnvalue>
11650 <entry role=
"func_table_entry"><para role=
"func_signature">
11651 <replaceable>geometric_type
</replaceable> <literal>&<</literal> <replaceable>geometric_type
</replaceable>
11652 <returnvalue>boolean
</returnvalue>
11655 Does first object not extend to the right of second?
11656 Available for
<type>box
</type>,
<type>polygon
</type>,
11657 <type>circle
</type>.
11660 <literal>box '(
1,
1),(
0,
0)'
&< box '(
2,
2),(
0,
0)'
</literal>
11661 <returnvalue>t
</returnvalue>
11666 <entry role=
"func_table_entry"><para role=
"func_signature">
11667 <replaceable>geometric_type
</replaceable> <literal>&></literal> <replaceable>geometric_type
</replaceable>
11668 <returnvalue>boolean
</returnvalue>
11671 Does first object not extend to the left of second?
11672 Available for
<type>box
</type>,
<type>polygon
</type>,
11673 <type>circle
</type>.
11676 <literal>box '(
3,
3),(
0,
0)'
&> box '(
2,
2),(
0,
0)'
</literal>
11677 <returnvalue>t
</returnvalue>
11682 <entry role=
"func_table_entry"><para role=
"func_signature">
11683 <replaceable>geometric_type
</replaceable> <literal><<|
</literal> <replaceable>geometric_type
</replaceable>
11684 <returnvalue>boolean
</returnvalue>
11687 Is first object strictly below second?
11688 Available for
<type>point
</type>,
<type>box
</type>,
<type>polygon
</type>,
11689 <type>circle
</type>.
11692 <literal>box '(
3,
3),(
0,
0)'
<<| box '(
5,
5),(
3,
4)'
</literal>
11693 <returnvalue>t
</returnvalue>
11698 <entry role=
"func_table_entry"><para role=
"func_signature">
11699 <replaceable>geometric_type
</replaceable> <literal>|
>></literal> <replaceable>geometric_type
</replaceable>
11700 <returnvalue>boolean
</returnvalue>
11703 Is first object strictly above second?
11704 Available for
<type>point
</type>,
<type>box
</type>,
<type>polygon
</type>,
11705 <type>circle
</type>.
11708 <literal>box '(
5,
5),(
3,
4)' |
>> box '(
3,
3),(
0,
0)'
</literal>
11709 <returnvalue>t
</returnvalue>
11714 <entry role=
"func_table_entry"><para role=
"func_signature">
11715 <replaceable>geometric_type
</replaceable> <literal>&<|
</literal> <replaceable>geometric_type
</replaceable>
11716 <returnvalue>boolean
</returnvalue>
11719 Does first object not extend above second?
11720 Available for
<type>box
</type>,
<type>polygon
</type>,
11721 <type>circle
</type>.
11724 <literal>box '(
1,
1),(
0,
0)'
&<| box '(
2,
2),(
0,
0)'
</literal>
11725 <returnvalue>t
</returnvalue>
11730 <entry role=
"func_table_entry"><para role=
"func_signature">
11731 <replaceable>geometric_type
</replaceable> <literal>|
&></literal> <replaceable>geometric_type
</replaceable>
11732 <returnvalue>boolean
</returnvalue>
11735 Does first object not extend below second?
11736 Available for
<type>box
</type>,
<type>polygon
</type>,
11737 <type>circle
</type>.
11740 <literal>box '(
3,
3),(
0,
0)' |
&> box '(
2,
2),(
0,
0)'
</literal>
11741 <returnvalue>t
</returnvalue>
11746 <entry role=
"func_table_entry"><para role=
"func_signature">
11747 <type>box
</type> <literal><^
</literal> <type>box
</type>
11748 <returnvalue>boolean
</returnvalue>
11751 Is first object below second (allows edges to touch)?
11754 <literal>box '((
1,
1),(
0,
0))'
<^ box '((
2,
2),(
1,
1))'
</literal>
11755 <returnvalue>t
</returnvalue>
11760 <entry role=
"func_table_entry"><para role=
"func_signature">
11761 <type>box
</type> <literal>>^
</literal> <type>box
</type>
11762 <returnvalue>boolean
</returnvalue>
11765 Is first object above second (allows edges to touch)?
11768 <literal>box '((
2,
2),(
1,
1))'
>^ box '((
1,
1),(
0,
0))'
</literal>
11769 <returnvalue>t
</returnvalue>
11774 <entry role=
"func_table_entry"><para role=
"func_signature">
11775 <replaceable>geometric_type
</replaceable> <literal>?#
</literal> <replaceable>geometric_type
</replaceable>
11776 <returnvalue>boolean
</returnvalue>
11779 Do these objects intersect?
11780 Available for these pairs of types:
11781 (
<type>box
</type>,
<type>box
</type>),
11782 (
<type>lseg
</type>,
<type>box
</type>),
11783 (
<type>lseg
</type>,
<type>lseg
</type>),
11784 (
<type>lseg
</type>,
<type>line
</type>),
11785 (
<type>line
</type>,
<type>box
</type>),
11786 (
<type>line
</type>,
<type>line
</type>),
11787 (
<type>path
</type>,
<type>path
</type>).
11790 <literal>lseg '[(-
1,
0),(
1,
0)]' ?# box '(
2,
2),(-
2,-
2)'
</literal>
11791 <returnvalue>t
</returnvalue>
11796 <entry role=
"func_table_entry"><para role=
"func_signature">
11797 <literal>?-
</literal> <type>line
</type>
11798 <returnvalue>boolean
</returnvalue>
11800 <para role=
"func_signature">
11801 <literal>?-
</literal> <type>lseg
</type>
11802 <returnvalue>boolean
</returnvalue>
11805 Is line horizontal?
11808 <literal>?- lseg '[(-
1,
0),(
1,
0)]'
</literal>
11809 <returnvalue>t
</returnvalue>
11814 <entry role=
"func_table_entry"><para role=
"func_signature">
11815 <type>point
</type> <literal>?-
</literal> <type>point
</type>
11816 <returnvalue>boolean
</returnvalue>
11819 Are points horizontally aligned (that is, have same y coordinate)?
11822 <literal>point '(
1,
0)' ?- point '(
0,
0)'
</literal>
11823 <returnvalue>t
</returnvalue>
11828 <entry role=
"func_table_entry"><para role=
"func_signature">
11829 <literal>?|
</literal> <type>line
</type>
11830 <returnvalue>boolean
</returnvalue>
11832 <para role=
"func_signature">
11833 <literal>?|
</literal> <type>lseg
</type>
11834 <returnvalue>boolean
</returnvalue>
11840 <literal>?| lseg '[(-
1,
0),(
1,
0)]'
</literal>
11841 <returnvalue>f
</returnvalue>
11846 <entry role=
"func_table_entry"><para role=
"func_signature">
11847 <type>point
</type> <literal>?|
</literal> <type>point
</type>
11848 <returnvalue>boolean
</returnvalue>
11851 Are points vertically aligned (that is, have same x coordinate)?
11854 <literal>point '(
0,
1)' ?| point '(
0,
0)'
</literal>
11855 <returnvalue>t
</returnvalue>
11860 <entry role=
"func_table_entry"><para role=
"func_signature">
11861 <type>line
</type> <literal>?-|
</literal> <type>line
</type>
11862 <returnvalue>boolean
</returnvalue>
11864 <para role=
"func_signature">
11865 <type>lseg
</type> <literal>?-|
</literal> <type>lseg
</type>
11866 <returnvalue>boolean
</returnvalue>
11869 Are lines perpendicular?
11872 <literal>lseg '[(
0,
0),(
0,
1)]' ?-| lseg '[(
0,
0),(
1,
0)]'
</literal>
11873 <returnvalue>t
</returnvalue>
11878 <entry role=
"func_table_entry"><para role=
"func_signature">
11879 <type>line
</type> <literal>?||
</literal> <type>line
</type>
11880 <returnvalue>boolean
</returnvalue>
11882 <para role=
"func_signature">
11883 <type>lseg
</type> <literal>?||
</literal> <type>lseg
</type>
11884 <returnvalue>boolean
</returnvalue>
11887 Are lines parallel?
11890 <literal>lseg '[(-
1,
0),(
1,
0)]' ?|| lseg '[(-
1,
2),(
1,
2)]'
</literal>
11891 <returnvalue>t
</returnvalue>
11896 <entry role=
"func_table_entry"><para role=
"func_signature">
11897 <replaceable>geometric_type
</replaceable> <literal>~=
</literal> <replaceable>geometric_type
</replaceable>
11898 <returnvalue>boolean
</returnvalue>
11901 Are these objects the same?
11902 Available for
<type>point
</type>,
<type>box
</type>,
11903 <type>polygon
</type>,
<type>circle
</type>.
11906 <literal>polygon '((
0,
0),(
1,
1))' ~= polygon '((
1,
1),(
0,
0))'
</literal>
11907 <returnvalue>t
</returnvalue>
11916 Note that the
<quote>same as
</quote> operator,
<literal>~=
</literal>,
11917 represents the usual notion of equality for the
<type>point
</type>,
11918 <type>box
</type>,
<type>polygon
</type>, and
<type>circle
</type> types.
11919 Some of the geometric types also have an
<literal>=
</literal> operator, but
11920 <literal>=
</literal> compares for equal
<emphasis>areas
</emphasis> only.
11921 The other scalar comparison operators (
<literal><=
</literal> and so
11922 on), where available for these types, likewise compare areas.
11928 Before
<productname>PostgreSQL
</productname> 14, the point
11929 is strictly below/above comparison operators
<type>point
</type>
11930 <literal><<|
</literal> <type>point
</type> and
<type>point
</type>
11931 <literal>|
>></literal> <type>point
</type> were respectively
11932 called
<literal><^
</literal> and
<literal>>^
</literal>. These
11933 names are still available, but are deprecated and will eventually be
11938 <table id=
"functions-geometry-func-table">
11939 <title>Geometric Functions
</title>
11943 <entry role=
"func_table_entry"><para role=
"func_signature">
11957 <entry role=
"func_table_entry"><para role=
"func_signature">
11959 <primary>area
</primary>
11961 <function>area
</function> (
<replaceable>geometric_type
</replaceable> )
11962 <returnvalue>double precision
</returnvalue>
11966 Available for
<type>box
</type>,
<type>path
</type>,
<type>circle
</type>.
11967 A
<type>path
</type> input must be closed, else NULL is returned.
11968 Also, if the
<type>path
</type> is self-intersecting, the result may be
11972 <literal>area(box '(
2,
2),(
0,
0)')
</literal>
11973 <returnvalue>4</returnvalue>
11978 <entry role=
"func_table_entry"><para role=
"func_signature">
11980 <primary>center
</primary>
11982 <function>center
</function> (
<replaceable>geometric_type
</replaceable> )
11983 <returnvalue>point
</returnvalue>
11986 Computes center point.
11987 Available for
<type>box
</type>,
<type>circle
</type>.
11990 <literal>center(box '(
1,
2),(
0,
0)')
</literal>
11991 <returnvalue>(
0.5,
1)
</returnvalue>
11996 <entry role=
"func_table_entry"><para role=
"func_signature">
11998 <primary>diagonal
</primary>
12000 <function>diagonal
</function> (
<type>box
</type> )
12001 <returnvalue>lseg
</returnvalue>
12004 Extracts box's diagonal as a line segment
12005 (same as
<function>lseg(box)
</function>).
12008 <literal>diagonal(box '(
1,
2),(
0,
0)')
</literal>
12009 <returnvalue>[(
1,
2),(
0,
0)]
</returnvalue>
12014 <entry role=
"func_table_entry"><para role=
"func_signature">
12016 <primary>diameter
</primary>
12018 <function>diameter
</function> (
<type>circle
</type> )
12019 <returnvalue>double precision
</returnvalue>
12022 Computes diameter of circle.
12025 <literal>diameter(circle '
<(
0,
0),
2>')
</literal>
12026 <returnvalue>4</returnvalue>
12031 <entry role=
"func_table_entry"><para role=
"func_signature">
12033 <primary>height
</primary>
12035 <function>height
</function> (
<type>box
</type> )
12036 <returnvalue>double precision
</returnvalue>
12039 Computes vertical size of box.
12042 <literal>height(box '(
1,
2),(
0,
0)')
</literal>
12043 <returnvalue>2</returnvalue>
12048 <entry role=
"func_table_entry"><para role=
"func_signature">
12050 <primary>isclosed
</primary>
12052 <function>isclosed
</function> (
<type>path
</type> )
12053 <returnvalue>boolean
</returnvalue>
12059 <literal>isclosed(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12060 <returnvalue>t
</returnvalue>
12065 <entry role=
"func_table_entry"><para role=
"func_signature">
12067 <primary>isopen
</primary>
12069 <function>isopen
</function> (
<type>path
</type> )
12070 <returnvalue>boolean
</returnvalue>
12076 <literal>isopen(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
12077 <returnvalue>t
</returnvalue>
12082 <entry role=
"func_table_entry"><para role=
"func_signature">
12084 <primary>length
</primary>
12086 <function>length
</function> (
<replaceable>geometric_type
</replaceable> )
12087 <returnvalue>double precision
</returnvalue>
12090 Computes the total length.
12091 Available for
<type>lseg
</type>,
<type>path
</type>.
12094 <literal>length(path '((-
1,
0),(
1,
0))')
</literal>
12095 <returnvalue>4</returnvalue>
12100 <entry role=
"func_table_entry"><para role=
"func_signature">
12102 <primary>npoints
</primary>
12104 <function>npoints
</function> (
<replaceable>geometric_type
</replaceable> )
12105 <returnvalue>integer
</returnvalue>
12108 Returns the number of points.
12109 Available for
<type>path
</type>,
<type>polygon
</type>.
12112 <literal>npoints(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
12113 <returnvalue>3</returnvalue>
12118 <entry role=
"func_table_entry"><para role=
"func_signature">
12120 <primary>pclose
</primary>
12122 <function>pclose
</function> (
<type>path
</type> )
12123 <returnvalue>path
</returnvalue>
12126 Converts path to closed form.
12129 <literal>pclose(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
12130 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12135 <entry role=
"func_table_entry"><para role=
"func_signature">
12137 <primary>popen
</primary>
12139 <function>popen
</function> (
<type>path
</type> )
12140 <returnvalue>path
</returnvalue>
12143 Converts path to open form.
12146 <literal>popen(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12147 <returnvalue>[(
0,
0),(
1,
1),(
2,
0)]
</returnvalue>
12152 <entry role=
"func_table_entry"><para role=
"func_signature">
12154 <primary>radius
</primary>
12156 <function>radius
</function> (
<type>circle
</type> )
12157 <returnvalue>double precision
</returnvalue>
12160 Computes radius of circle.
12163 <literal>radius(circle '
<(
0,
0),
2>')
</literal>
12164 <returnvalue>2</returnvalue>
12169 <entry role=
"func_table_entry"><para role=
"func_signature">
12171 <primary>slope
</primary>
12173 <function>slope
</function> (
<type>point
</type>,
<type>point
</type> )
12174 <returnvalue>double precision
</returnvalue>
12177 Computes slope of a line drawn through the two points.
12180 <literal>slope(point '(
0,
0)', point '(
2,
1)')
</literal>
12181 <returnvalue>0.5</returnvalue>
12186 <entry role=
"func_table_entry"><para role=
"func_signature">
12188 <primary>width
</primary>
12190 <function>width
</function> (
<type>box
</type> )
12191 <returnvalue>double precision
</returnvalue>
12194 Computes horizontal size of box.
12197 <literal>width(box '(
1,
2),(
0,
0)')
</literal>
12198 <returnvalue>1</returnvalue>
12205 <table id=
"functions-geometry-conv-table">
12206 <title>Geometric Type Conversion Functions
</title>
12210 <entry role=
"func_table_entry"><para role=
"func_signature">
12224 <entry role=
"func_table_entry"><para role=
"func_signature">
12226 <primary>box
</primary>
12228 <function>box
</function> (
<type>circle
</type> )
12229 <returnvalue>box
</returnvalue>
12232 Computes box inscribed within the circle.
12235 <literal>box(circle '
<(
0,
0),
2>')
</literal>
12236 <returnvalue>(
1.414213562373095,
1.414213562373095),
&zwsp;(-
1.414213562373095,-
1.414213562373095)
</returnvalue>
12241 <entry role=
"func_table_entry"><para role=
"func_signature">
12242 <function>box
</function> (
<type>point
</type> )
12243 <returnvalue>box
</returnvalue>
12246 Converts point to empty box.
12249 <literal>box(point '(
1,
0)')
</literal>
12250 <returnvalue>(
1,
0),(
1,
0)
</returnvalue>
12255 <entry role=
"func_table_entry"><para role=
"func_signature">
12256 <function>box
</function> (
<type>point
</type>,
<type>point
</type> )
12257 <returnvalue>box
</returnvalue>
12260 Converts any two corner points to box.
12263 <literal>box(point '(
0,
1)', point '(
1,
0)')
</literal>
12264 <returnvalue>(
1,
1),(
0,
0)
</returnvalue>
12269 <entry role=
"func_table_entry"><para role=
"func_signature">
12270 <function>box
</function> (
<type>polygon
</type> )
12271 <returnvalue>box
</returnvalue>
12274 Computes bounding box of polygon.
12277 <literal>box(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12278 <returnvalue>(
2,
1),(
0,
0)
</returnvalue>
12283 <entry role=
"func_table_entry"><para role=
"func_signature">
12285 <primary>bound_box
</primary>
12287 <function>bound_box
</function> (
<type>box
</type>,
<type>box
</type> )
12288 <returnvalue>box
</returnvalue>
12291 Computes bounding box of two boxes.
12294 <literal>bound_box(box '(
1,
1),(
0,
0)', box '(
4,
4),(
3,
3)')
</literal>
12295 <returnvalue>(
4,
4),(
0,
0)
</returnvalue>
12300 <entry role=
"func_table_entry"><para role=
"func_signature">
12302 <primary>circle
</primary>
12304 <function>circle
</function> (
<type>box
</type> )
12305 <returnvalue>circle
</returnvalue>
12308 Computes smallest circle enclosing box.
12311 <literal>circle(box '(
1,
1),(
0,
0)')
</literal>
12312 <returnvalue><(
0.5,
0.5),
0.7071067811865476></returnvalue>
12317 <entry role=
"func_table_entry"><para role=
"func_signature">
12318 <function>circle
</function> (
<type>point
</type>,
<type>double precision
</type> )
12319 <returnvalue>circle
</returnvalue>
12322 Constructs circle from center and radius.
12325 <literal>circle(point '(
0,
0)',
2.0)
</literal>
12326 <returnvalue><(
0,
0),
2></returnvalue>
12331 <entry role=
"func_table_entry"><para role=
"func_signature">
12332 <function>circle
</function> (
<type>polygon
</type> )
12333 <returnvalue>circle
</returnvalue>
12336 Converts polygon to circle. The circle's center is the mean of the
12337 positions of the polygon's points, and the radius is the average
12338 distance of the polygon's points from that center.
12341 <literal>circle(polygon '((
0,
0),(
1,
3),(
2,
0))')
</literal>
12342 <returnvalue><(
1,
1),
1.6094757082487299></returnvalue>
12347 <entry role=
"func_table_entry"><para role=
"func_signature">
12349 <primary>line
</primary>
12351 <function>line
</function> (
<type>point
</type>,
<type>point
</type> )
12352 <returnvalue>line
</returnvalue>
12355 Converts two points to the line through them.
12358 <literal>line(point '(-
1,
0)', point '(
1,
0)')
</literal>
12359 <returnvalue>{
0,-
1,
0}
</returnvalue>
12364 <entry role=
"func_table_entry"><para role=
"func_signature">
12366 <primary>lseg
</primary>
12368 <function>lseg
</function> (
<type>box
</type> )
12369 <returnvalue>lseg
</returnvalue>
12372 Extracts box's diagonal as a line segment.
12375 <literal>lseg(box '(
1,
0),(-
1,
0)')
</literal>
12376 <returnvalue>[(
1,
0),(-
1,
0)]
</returnvalue>
12381 <entry role=
"func_table_entry"><para role=
"func_signature">
12382 <function>lseg
</function> (
<type>point
</type>,
<type>point
</type> )
12383 <returnvalue>lseg
</returnvalue>
12386 Constructs line segment from two endpoints.
12389 <literal>lseg(point '(-
1,
0)', point '(
1,
0)')
</literal>
12390 <returnvalue>[(-
1,
0),(
1,
0)]
</returnvalue>
12395 <entry role=
"func_table_entry"><para role=
"func_signature">
12397 <primary>path
</primary>
12399 <function>path
</function> (
<type>polygon
</type> )
12400 <returnvalue>path
</returnvalue>
12403 Converts polygon to a closed path with the same list of points.
12406 <literal>path(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12407 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12412 <entry role=
"func_table_entry"><para role=
"func_signature">
12414 <primary>point
</primary>
12416 <function>point
</function> (
<type>double precision
</type>,
<type>double precision
</type> )
12417 <returnvalue>point
</returnvalue>
12420 Constructs point from its coordinates.
12423 <literal>point(
23.4, -
44.5)
</literal>
12424 <returnvalue>(
23.4,-
44.5)
</returnvalue>
12429 <entry role=
"func_table_entry"><para role=
"func_signature">
12430 <function>point
</function> (
<type>box
</type> )
12431 <returnvalue>point
</returnvalue>
12434 Computes center of box.
12437 <literal>point(box '(
1,
0),(-
1,
0)')
</literal>
12438 <returnvalue>(
0,
0)
</returnvalue>
12443 <entry role=
"func_table_entry"><para role=
"func_signature">
12444 <function>point
</function> (
<type>circle
</type> )
12445 <returnvalue>point
</returnvalue>
12448 Computes center of circle.
12451 <literal>point(circle '
<(
0,
0),
2>')
</literal>
12452 <returnvalue>(
0,
0)
</returnvalue>
12457 <entry role=
"func_table_entry"><para role=
"func_signature">
12458 <function>point
</function> (
<type>lseg
</type> )
12459 <returnvalue>point
</returnvalue>
12462 Computes center of line segment.
12465 <literal>point(lseg '[(-
1,
0),(
1,
0)]')
</literal>
12466 <returnvalue>(
0,
0)
</returnvalue>
12471 <entry role=
"func_table_entry"><para role=
"func_signature">
12472 <function>point
</function> (
<type>polygon
</type> )
12473 <returnvalue>point
</returnvalue>
12476 Computes center of polygon (the mean of the
12477 positions of the polygon's points).
12480 <literal>point(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12481 <returnvalue>(
1,
0.3333333333333333)
</returnvalue>
12486 <entry role=
"func_table_entry"><para role=
"func_signature">
12488 <primary>polygon
</primary>
12490 <function>polygon
</function> (
<type>box
</type> )
12491 <returnvalue>polygon
</returnvalue>
12494 Converts box to a
4-point polygon.
12497 <literal>polygon(box '(
1,
1),(
0,
0)')
</literal>
12498 <returnvalue>((
0,
0),(
0,
1),(
1,
1),(
1,
0))
</returnvalue>
12503 <entry role=
"func_table_entry"><para role=
"func_signature">
12504 <function>polygon
</function> (
<type>circle
</type> )
12505 <returnvalue>polygon
</returnvalue>
12508 Converts circle to a
12-point polygon.
12511 <literal>polygon(circle '
<(
0,
0),
2>')
</literal>
12512 <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>
12517 <entry role=
"func_table_entry"><para role=
"func_signature">
12518 <function>polygon
</function> (
<type>integer
</type>,
<type>circle
</type> )
12519 <returnvalue>polygon
</returnvalue>
12522 Converts circle to an
<replaceable>n
</replaceable>-point polygon.
12525 <literal>polygon(
4, circle '
<(
3,
0),
1>')
</literal>
12526 <returnvalue>((
2,
0),
&zwsp;(
3,
1),
&zwsp;(
4,
1.2246063538223773e-16),
&zwsp;(
3,-
1))
</returnvalue>
12531 <entry role=
"func_table_entry"><para role=
"func_signature">
12532 <function>polygon
</function> (
<type>path
</type> )
12533 <returnvalue>polygon
</returnvalue>
12536 Converts closed path to a polygon with the same list of points.
12539 <literal>polygon(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12540 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12549 It is possible to access the two component numbers of a
<type>point
</type>
12550 as though the point were an array with indexes
0 and
1. For example, if
12551 <literal>t.p
</literal> is a
<type>point
</type> column then
12552 <literal>SELECT p[
0] FROM t
</literal> retrieves the X coordinate and
12553 <literal>UPDATE t SET p[
1] = ...
</literal> changes the Y coordinate.
12554 In the same way, a value of type
<type>box
</type> or
<type>lseg
</type> can be treated
12555 as an array of two
<type>point
</type> values.
12561 <sect1 id=
"functions-net">
12562 <title>Network Address Functions and Operators
</title>
12565 The IP network address types,
<type>cidr
</type> and
<type>inet
</type>,
12566 support the usual comparison operators shown in
12567 <xref linkend=
"functions-comparison-op-table"/>
12568 as well as the specialized operators and functions shown in
12569 <xref linkend=
"cidr-inet-operators-table"/> and
12570 <xref linkend=
"cidr-inet-functions-table"/>.
12574 Any
<type>cidr
</type> value can be cast to
<type>inet
</type> implicitly;
12575 therefore, the operators and functions shown below as operating on
12576 <type>inet
</type> also work on
<type>cidr
</type> values. (Where there are
12577 separate functions for
<type>inet
</type> and
<type>cidr
</type>, it is
12578 because the behavior should be different for the two cases.)
12579 Also, it is permitted to cast an
<type>inet
</type> value
12580 to
<type>cidr
</type>. When this is done, any bits to the right of the
12581 netmask are silently zeroed to create a valid
<type>cidr
</type> value.
12584 <table id=
"cidr-inet-operators-table">
12585 <title>IP Address Operators
</title>
12589 <entry role=
"func_table_entry"><para role=
"func_signature">
12603 <entry role=
"func_table_entry"><para role=
"func_signature">
12604 <type>inet
</type> <literal><<</literal> <type>inet
</type>
12605 <returnvalue>boolean
</returnvalue>
12608 Is subnet strictly contained by subnet?
12609 This operator, and the next four, test for subnet inclusion. They
12610 consider only the network parts of the two addresses (ignoring any
12611 bits to the right of the netmasks) and determine whether one network
12612 is identical to or a subnet of the other.
12615 <literal>inet '
192.168.1.5'
<< inet '
192.168.1/
24'
</literal>
12616 <returnvalue>t
</returnvalue>
12619 <literal>inet '
192.168.0.5'
<< inet '
192.168.1/
24'
</literal>
12620 <returnvalue>f
</returnvalue>
12623 <literal>inet '
192.168.1/
24'
<< inet '
192.168.1/
24'
</literal>
12624 <returnvalue>f
</returnvalue>
12629 <entry role=
"func_table_entry"><para role=
"func_signature">
12630 <type>inet
</type> <literal><<=
</literal> <type>inet
</type>
12631 <returnvalue>boolean
</returnvalue>
12634 Is subnet contained by or equal to subnet?
12637 <literal>inet '
192.168.1/
24'
<<= inet '
192.168.1/
24'
</literal>
12638 <returnvalue>t
</returnvalue>
12643 <entry role=
"func_table_entry"><para role=
"func_signature">
12644 <type>inet
</type> <literal>>></literal> <type>inet
</type>
12645 <returnvalue>boolean
</returnvalue>
12648 Does subnet strictly contain subnet?
12651 <literal>inet '
192.168.1/
24'
>> inet '
192.168.1.5'
</literal>
12652 <returnvalue>t
</returnvalue>
12657 <entry role=
"func_table_entry"><para role=
"func_signature">
12658 <type>inet
</type> <literal>>>=
</literal> <type>inet
</type>
12659 <returnvalue>boolean
</returnvalue>
12662 Does subnet contain or equal subnet?
12665 <literal>inet '
192.168.1/
24'
>>= inet '
192.168.1/
24'
</literal>
12666 <returnvalue>t
</returnvalue>
12671 <entry role=
"func_table_entry"><para role=
"func_signature">
12672 <type>inet
</type> <literal>&&</literal> <type>inet
</type>
12673 <returnvalue>boolean
</returnvalue>
12676 Does either subnet contain or equal the other?
12679 <literal>inet '
192.168.1/
24'
&& inet '
192.168.1.80/
28'
</literal>
12680 <returnvalue>t
</returnvalue>
12683 <literal>inet '
192.168.1/
24'
&& inet '
192.168.2.0/
28'
</literal>
12684 <returnvalue>f
</returnvalue>
12689 <entry role=
"func_table_entry"><para role=
"func_signature">
12690 <literal>~
</literal> <type>inet
</type>
12691 <returnvalue>inet
</returnvalue>
12694 Computes bitwise NOT.
12697 <literal>~ inet '
192.168.1.6'
</literal>
12698 <returnvalue>63.87.254.249</returnvalue>
12703 <entry role=
"func_table_entry"><para role=
"func_signature">
12704 <type>inet
</type> <literal>&</literal> <type>inet
</type>
12705 <returnvalue>inet
</returnvalue>
12708 Computes bitwise AND.
12711 <literal>inet '
192.168.1.6'
& inet '
0.0.0.255'
</literal>
12712 <returnvalue>0.0.0.6</returnvalue>
12717 <entry role=
"func_table_entry"><para role=
"func_signature">
12718 <type>inet
</type> <literal>|
</literal> <type>inet
</type>
12719 <returnvalue>inet
</returnvalue>
12722 Computes bitwise OR.
12725 <literal>inet '
192.168.1.6' | inet '
0.0.0.255'
</literal>
12726 <returnvalue>192.168.1.255</returnvalue>
12731 <entry role=
"func_table_entry"><para role=
"func_signature">
12732 <type>inet
</type> <literal>+
</literal> <type>bigint
</type>
12733 <returnvalue>inet
</returnvalue>
12736 Adds an offset to an address.
12739 <literal>inet '
192.168.1.6' +
25</literal>
12740 <returnvalue>192.168.1.31</returnvalue>
12745 <entry role=
"func_table_entry"><para role=
"func_signature">
12746 <type>bigint
</type> <literal>+
</literal> <type>inet
</type>
12747 <returnvalue>inet
</returnvalue>
12750 Adds an offset to an address.
12753 <literal>200 + inet '::ffff:fff0:
1'
</literal>
12754 <returnvalue>::ffff:
255.240.0.201</returnvalue>
12759 <entry role=
"func_table_entry"><para role=
"func_signature">
12760 <type>inet
</type> <literal>-
</literal> <type>bigint
</type>
12761 <returnvalue>inet
</returnvalue>
12764 Subtracts an offset from an address.
12767 <literal>inet '
192.168.1.43' -
36</literal>
12768 <returnvalue>192.168.1.7</returnvalue>
12773 <entry role=
"func_table_entry"><para role=
"func_signature">
12774 <type>inet
</type> <literal>-
</literal> <type>inet
</type>
12775 <returnvalue>bigint
</returnvalue>
12778 Computes the difference of two addresses.
12781 <literal>inet '
192.168.1.43' - inet '
192.168.1.19'
</literal>
12782 <returnvalue>24</returnvalue>
12785 <literal>inet '::
1' - inet '::ffff:
1'
</literal>
12786 <returnvalue>-
4294901760</returnvalue>
12793 <table id=
"cidr-inet-functions-table">
12794 <title>IP Address Functions
</title>
12798 <entry role=
"func_table_entry"><para role=
"func_signature">
12812 <entry role=
"func_table_entry"><para role=
"func_signature">
12814 <primary>abbrev
</primary>
12816 <function>abbrev
</function> (
<type>inet
</type> )
12817 <returnvalue>text
</returnvalue>
12820 Creates an abbreviated display format as text.
12821 (The result is the same as the
<type>inet
</type> output function
12822 produces; it is
<quote>abbreviated
</quote> only in comparison to the
12823 result of an explicit cast to
<type>text
</type>, which for historical
12824 reasons will never suppress the netmask part.)
12827 <literal>abbrev(inet '
10.1.0.0/
32')
</literal>
12828 <returnvalue>10.1.0.0</returnvalue>
12833 <entry role=
"func_table_entry"><para role=
"func_signature">
12834 <function>abbrev
</function> (
<type>cidr
</type> )
12835 <returnvalue>text
</returnvalue>
12838 Creates an abbreviated display format as text.
12839 (The abbreviation consists of dropping all-zero octets to the right
12840 of the netmask; more examples are in
12841 <xref linkend=
"datatype-net-cidr-table"/>.)
12844 <literal>abbrev(cidr '
10.1.0.0/
16')
</literal>
12845 <returnvalue>10.1/
16</returnvalue>
12850 <entry role=
"func_table_entry"><para role=
"func_signature">
12852 <primary>broadcast
</primary>
12854 <function>broadcast
</function> (
<type>inet
</type> )
12855 <returnvalue>inet
</returnvalue>
12858 Computes the broadcast address for the address's network.
12861 <literal>broadcast(inet '
192.168.1.5/
24')
</literal>
12862 <returnvalue>192.168.1.255/
24</returnvalue>
12867 <entry role=
"func_table_entry"><para role=
"func_signature">
12869 <primary>family
</primary>
12871 <function>family
</function> (
<type>inet
</type> )
12872 <returnvalue>integer
</returnvalue>
12875 Returns the address's family:
<literal>4</literal> for IPv4,
12876 <literal>6</literal> for IPv6.
12879 <literal>family(inet '::
1')
</literal>
12880 <returnvalue>6</returnvalue>
12885 <entry role=
"func_table_entry"><para role=
"func_signature">
12887 <primary>host
</primary>
12889 <function>host
</function> (
<type>inet
</type> )
12890 <returnvalue>text
</returnvalue>
12893 Returns the IP address as text, ignoring the netmask.
12896 <literal>host(inet '
192.168.1.0/
24')
</literal>
12897 <returnvalue>192.168.1.0</returnvalue>
12902 <entry role=
"func_table_entry"><para role=
"func_signature">
12904 <primary>hostmask
</primary>
12906 <function>hostmask
</function> (
<type>inet
</type> )
12907 <returnvalue>inet
</returnvalue>
12910 Computes the host mask for the address's network.
12913 <literal>hostmask(inet '
192.168.23.20/
30')
</literal>
12914 <returnvalue>0.0.0.3</returnvalue>
12919 <entry role=
"func_table_entry"><para role=
"func_signature">
12921 <primary>inet_merge
</primary>
12923 <function>inet_merge
</function> (
<type>inet
</type>,
<type>inet
</type> )
12924 <returnvalue>cidr
</returnvalue>
12927 Computes the smallest network that includes both of the given networks.
12930 <literal>inet_merge(inet '
192.168.1.5/
24', inet '
192.168.2.5/
24')
</literal>
12931 <returnvalue>192.168.0.0/
22</returnvalue>
12936 <entry role=
"func_table_entry"><para role=
"func_signature">
12938 <primary>inet_same_family
</primary>
12940 <function>inet_same_family
</function> (
<type>inet
</type>,
<type>inet
</type> )
12941 <returnvalue>boolean
</returnvalue>
12944 Tests whether the addresses belong to the same IP family.
12947 <literal>inet_same_family(inet '
192.168.1.5/
24', inet '::
1')
</literal>
12948 <returnvalue>f
</returnvalue>
12953 <entry role=
"func_table_entry"><para role=
"func_signature">
12955 <primary>masklen
</primary>
12957 <function>masklen
</function> (
<type>inet
</type> )
12958 <returnvalue>integer
</returnvalue>
12961 Returns the netmask length in bits.
12964 <literal>masklen(inet '
192.168.1.5/
24')
</literal>
12965 <returnvalue>24</returnvalue>
12970 <entry role=
"func_table_entry"><para role=
"func_signature">
12972 <primary>netmask
</primary>
12974 <function>netmask
</function> (
<type>inet
</type> )
12975 <returnvalue>inet
</returnvalue>
12978 Computes the network mask for the address's network.
12981 <literal>netmask(inet '
192.168.1.5/
24')
</literal>
12982 <returnvalue>255.255.255.0</returnvalue>
12987 <entry role=
"func_table_entry"><para role=
"func_signature">
12989 <primary>network
</primary>
12991 <function>network
</function> (
<type>inet
</type> )
12992 <returnvalue>cidr
</returnvalue>
12995 Returns the network part of the address, zeroing out
12996 whatever is to the right of the netmask.
12997 (This is equivalent to casting the value to
<type>cidr
</type>.)
13000 <literal>network(inet '
192.168.1.5/
24')
</literal>
13001 <returnvalue>192.168.1.0/
24</returnvalue>
13006 <entry role=
"func_table_entry"><para role=
"func_signature">
13008 <primary>set_masklen
</primary>
13010 <function>set_masklen
</function> (
<type>inet
</type>,
<type>integer
</type> )
13011 <returnvalue>inet
</returnvalue>
13014 Sets the netmask length for an
<type>inet
</type> value.
13015 The address part does not change.
13018 <literal>set_masklen(inet '
192.168.1.5/
24',
16)
</literal>
13019 <returnvalue>192.168.1.5/
16</returnvalue>
13024 <entry role=
"func_table_entry"><para role=
"func_signature">
13025 <function>set_masklen
</function> (
<type>cidr
</type>,
<type>integer
</type> )
13026 <returnvalue>cidr
</returnvalue>
13029 Sets the netmask length for a
<type>cidr
</type> value.
13030 Address bits to the right of the new netmask are set to zero.
13033 <literal>set_masklen(cidr '
192.168.1.0/
24',
16)
</literal>
13034 <returnvalue>192.168.0.0/
16</returnvalue>
13039 <entry role=
"func_table_entry"><para role=
"func_signature">
13041 <primary>text
</primary>
13043 <function>text
</function> (
<type>inet
</type> )
13044 <returnvalue>text
</returnvalue>
13047 Returns the unabbreviated IP address and netmask length as text.
13048 (This has the same result as an explicit cast to
<type>text
</type>.)
13051 <literal>text(inet '
192.168.1.5')
</literal>
13052 <returnvalue>192.168.1.5/
32</returnvalue>
13061 The
<function>abbrev
</function>,
<function>host
</function>,
13062 and
<function>text
</function> functions are primarily intended to offer
13063 alternative display formats for IP addresses.
13068 The MAC address types,
<type>macaddr
</type> and
<type>macaddr8
</type>,
13069 support the usual comparison operators shown in
13070 <xref linkend=
"functions-comparison-op-table"/>
13071 as well as the specialized functions shown in
13072 <xref linkend=
"macaddr-functions-table"/>.
13073 In addition, they support the bitwise logical operators
13074 <literal>~
</literal>,
<literal>&</literal> and
<literal>|
</literal>
13075 (NOT, AND and OR), just as shown above for IP addresses.
13078 <table id=
"macaddr-functions-table">
13079 <title>MAC Address Functions
</title>
13083 <entry role=
"func_table_entry"><para role=
"func_signature">
13097 <entry role=
"func_table_entry"><para role=
"func_signature">
13099 <primary>trunc
</primary>
13101 <function>trunc
</function> (
<type>macaddr
</type> )
13102 <returnvalue>macaddr
</returnvalue>
13105 Sets the last
3 bytes of the address to zero. The remaining prefix
13106 can be associated with a particular manufacturer (using data not
13107 included in
<productname>PostgreSQL
</productname>).
13110 <literal>trunc(macaddr '
12:
34:
56:
78:
90:ab')
</literal>
13111 <returnvalue>12:
34:
56:
00:
00:
00</returnvalue>
13116 <entry role=
"func_table_entry"><para role=
"func_signature">
13117 <function>trunc
</function> (
<type>macaddr8
</type> )
13118 <returnvalue>macaddr8
</returnvalue>
13121 Sets the last
5 bytes of the address to zero. The remaining prefix
13122 can be associated with a particular manufacturer (using data not
13123 included in
<productname>PostgreSQL
</productname>).
13126 <literal>trunc(macaddr8 '
12:
34:
56:
78:
90:ab:cd:ef')
</literal>
13127 <returnvalue>12:
34:
56:
00:
00:
00:
00:
00</returnvalue>
13132 <entry role=
"func_table_entry"><para role=
"func_signature">
13134 <primary>macaddr8_set7bit
</primary>
13136 <function>macaddr8_set7bit
</function> (
<type>macaddr8
</type> )
13137 <returnvalue>macaddr8
</returnvalue>
13140 Sets the
7th bit of the address to one, creating what is known as
13141 modified EUI-
64, for inclusion in an IPv6 address.
13144 <literal>macaddr8_set7bit(macaddr8 '
00:
34:
56:ab:cd:ef')
</literal>
13145 <returnvalue>02:
34:
56:ff:fe:ab:cd:ef
</returnvalue>
13155 <sect1 id=
"functions-textsearch">
13156 <title>Text Search Functions and Operators
</title>
13158 <indexterm zone=
"datatype-textsearch">
13159 <primary>full text search
</primary>
13160 <secondary>functions and operators
</secondary>
13163 <indexterm zone=
"datatype-textsearch">
13164 <primary>text search
</primary>
13165 <secondary>functions and operators
</secondary>
13169 <xref linkend=
"textsearch-operators-table"/>,
13170 <xref linkend=
"textsearch-functions-table"/> and
13171 <xref linkend=
"textsearch-functions-debug-table"/>
13172 summarize the functions and operators that are provided
13173 for full text searching. See
<xref linkend=
"textsearch"/> for a detailed
13174 explanation of
<productname>PostgreSQL
</productname>'s text search
13178 <table id=
"textsearch-operators-table">
13179 <title>Text Search Operators
</title>
13183 <entry role=
"func_table_entry"><para role=
"func_signature">
13197 <entry role=
"func_table_entry"><para role=
"func_signature">
13198 <type>tsvector
</type> <literal>@@
</literal> <type>tsquery
</type>
13199 <returnvalue>boolean
</returnvalue>
13201 <para role=
"func_signature">
13202 <type>tsquery
</type> <literal>@@
</literal> <type>tsvector
</type>
13203 <returnvalue>boolean
</returnvalue>
13206 Does
<type>tsvector
</type> match
<type>tsquery
</type>?
13207 (The arguments can be given in either order.)
13210 <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat
& rat')
</literal>
13211 <returnvalue>t
</returnvalue>
13216 <entry role=
"func_table_entry"><para role=
"func_signature">
13217 <type>text
</type> <literal>@@
</literal> <type>tsquery
</type>
13218 <returnvalue>boolean
</returnvalue>
13221 Does text string, after implicit invocation
13222 of
<function>to_tsvector()
</function>, match
<type>tsquery
</type>?
13225 <literal>'fat cats ate rats' @@ to_tsquery('cat
& rat')
</literal>
13226 <returnvalue>t
</returnvalue>
13231 <entry role=
"func_table_entry"><para role=
"func_signature">
13232 <type>tsvector
</type> <literal>||
</literal> <type>tsvector
</type>
13233 <returnvalue>tsvector
</returnvalue>
13236 Concatenates two
<type>tsvector
</type>s. If both inputs contain
13237 lexeme positions, the second input's positions are adjusted
13241 <literal>'a:
1 b:
2'::tsvector || 'c:
1 d:
2 b:
3'::tsvector
</literal>
13242 <returnvalue>'a':
1 'b':
2,
5 'c':
3 'd':
4</returnvalue>
13247 <entry role=
"func_table_entry"><para role=
"func_signature">
13248 <type>tsquery
</type> <literal>&&</literal> <type>tsquery
</type>
13249 <returnvalue>tsquery
</returnvalue>
13252 ANDs two
<type>tsquery
</type>s together, producing a query that
13253 matches documents that match both input queries.
13256 <literal>'fat | rat'::tsquery
&& 'cat'::tsquery
</literal>
13257 <returnvalue>( 'fat' | 'rat' )
& 'cat'
</returnvalue>
13262 <entry role=
"func_table_entry"><para role=
"func_signature">
13263 <type>tsquery
</type> <literal>||
</literal> <type>tsquery
</type>
13264 <returnvalue>tsquery
</returnvalue>
13267 ORs two
<type>tsquery
</type>s together, producing a query that
13268 matches documents that match either input query.
13271 <literal>'fat | rat'::tsquery || 'cat'::tsquery
</literal>
13272 <returnvalue>'fat' | 'rat' | 'cat'
</returnvalue>
13277 <entry role=
"func_table_entry"><para role=
"func_signature">
13278 <literal>!!
</literal> <type>tsquery
</type>
13279 <returnvalue>tsquery
</returnvalue>
13282 Negates a
<type>tsquery
</type>, producing a query that matches
13283 documents that do not match the input query.
13286 <literal>!! 'cat'::tsquery
</literal>
13287 <returnvalue>!'cat'
</returnvalue>
13292 <entry role=
"func_table_entry"><para role=
"func_signature">
13293 <type>tsquery
</type> <literal><-
></literal> <type>tsquery
</type>
13294 <returnvalue>tsquery
</returnvalue>
13297 Constructs a phrase query, which matches if the two input queries
13298 match at successive lexemes.
13301 <literal>to_tsquery('fat')
<-
> to_tsquery('rat')
</literal>
13302 <returnvalue>'fat'
<-
> 'rat'
</returnvalue>
13307 <entry role=
"func_table_entry"><para role=
"func_signature">
13308 <type>tsquery
</type> <literal>@
></literal> <type>tsquery
</type>
13309 <returnvalue>boolean
</returnvalue>
13312 Does first
<type>tsquery
</type> contain the second? (This considers
13313 only whether all the lexemes appearing in one query appear in the
13314 other, ignoring the combining operators.)
13317 <literal>'cat'::tsquery @
> 'cat
& rat'::tsquery
</literal>
13318 <returnvalue>f
</returnvalue>
13323 <entry role=
"func_table_entry"><para role=
"func_signature">
13324 <type>tsquery
</type> <literal><@
</literal> <type>tsquery
</type>
13325 <returnvalue>boolean
</returnvalue>
13328 Is first
<type>tsquery
</type> contained in the second? (This
13329 considers only whether all the lexemes appearing in one query appear
13330 in the other, ignoring the combining operators.)
13333 <literal>'cat'::tsquery
<@ 'cat
& rat'::tsquery
</literal>
13334 <returnvalue>t
</returnvalue>
13337 <literal>'cat'::tsquery
<@ '!cat
& rat'::tsquery
</literal>
13338 <returnvalue>t
</returnvalue>
13346 In addition to these specialized operators, the usual comparison
13347 operators shown in
<xref linkend=
"functions-comparison-op-table"/> are
13348 available for types
<type>tsvector
</type> and
<type>tsquery
</type>.
13350 useful for text searching but allow, for example, unique indexes to be
13351 built on columns of these types.
13354 <table id=
"textsearch-functions-table">
13355 <title>Text Search Functions
</title>
13359 <entry role=
"func_table_entry"><para role=
"func_signature">
13373 <entry role=
"func_table_entry"><para role=
"func_signature">
13375 <primary>array_to_tsvector
</primary>
13377 <function>array_to_tsvector
</function> (
<type>text[]
</type> )
13378 <returnvalue>tsvector
</returnvalue>
13381 Converts an array of text strings to a
<type>tsvector
</type>.
13382 The given strings are used as lexemes as-is, without further
13383 processing. Array elements must not be empty strings
13384 or
<literal>NULL
</literal>.
13387 <literal>array_to_tsvector('{fat,cat,rat}'::text[])
</literal>
13388 <returnvalue>'cat' 'fat' 'rat'
</returnvalue>
13393 <entry role=
"func_table_entry"><para role=
"func_signature">
13395 <primary>get_current_ts_config
</primary>
13397 <function>get_current_ts_config
</function> ( )
13398 <returnvalue>regconfig
</returnvalue>
13401 Returns the OID of the current default text search configuration
13402 (as set by
<xref linkend=
"guc-default-text-search-config"/>).
13405 <literal>get_current_ts_config()
</literal>
13406 <returnvalue>english
</returnvalue>
13411 <entry role=
"func_table_entry"><para role=
"func_signature">
13413 <primary>length
</primary>
13415 <function>length
</function> (
<type>tsvector
</type> )
13416 <returnvalue>integer
</returnvalue>
13419 Returns the number of lexemes in the
<type>tsvector
</type>.
13422 <literal>length('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13423 <returnvalue>3</returnvalue>
13428 <entry role=
"func_table_entry"><para role=
"func_signature">
13430 <primary>numnode
</primary>
13432 <function>numnode
</function> (
<type>tsquery
</type> )
13433 <returnvalue>integer
</returnvalue>
13436 Returns the number of lexemes plus operators in
13437 the
<type>tsquery
</type>.
13440 <literal>numnode('(fat
& rat) | cat'::tsquery)
</literal>
13441 <returnvalue>5</returnvalue>
13446 <entry role=
"func_table_entry"><para role=
"func_signature">
13448 <primary>plainto_tsquery
</primary>
13450 <function>plainto_tsquery
</function> (
13451 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13452 <parameter>query
</parameter> <type>text
</type> )
13453 <returnvalue>tsquery
</returnvalue>
13456 Converts text to a
<type>tsquery
</type>, normalizing words according to
13457 the specified or default configuration. Any punctuation in the string
13458 is ignored (it does not determine query operators). The resulting
13459 query matches documents containing all non-stopwords in the text.
13462 <literal>plainto_tsquery('english', 'The Fat Rats')
</literal>
13463 <returnvalue>'fat'
& 'rat'
</returnvalue>
13468 <entry role=
"func_table_entry"><para role=
"func_signature">
13470 <primary>phraseto_tsquery
</primary>
13472 <function>phraseto_tsquery
</function> (
13473 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13474 <parameter>query
</parameter> <type>text
</type> )
13475 <returnvalue>tsquery
</returnvalue>
13478 Converts text to a
<type>tsquery
</type>, normalizing words according to
13479 the specified or default configuration. Any punctuation in the string
13480 is ignored (it does not determine query operators). The resulting
13481 query matches phrases containing all non-stopwords in the text.
13484 <literal>phraseto_tsquery('english', 'The Fat Rats')
</literal>
13485 <returnvalue>'fat'
<-
> 'rat'
</returnvalue>
13488 <literal>phraseto_tsquery('english', 'The Cat and Rats')
</literal>
13489 <returnvalue>'cat'
<2> 'rat'
</returnvalue>
13494 <entry role=
"func_table_entry"><para role=
"func_signature">
13496 <primary>websearch_to_tsquery
</primary>
13498 <function>websearch_to_tsquery
</function> (
13499 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13500 <parameter>query
</parameter> <type>text
</type> )
13501 <returnvalue>tsquery
</returnvalue>
13504 Converts text to a
<type>tsquery
</type>, normalizing words according
13505 to the specified or default configuration. Quoted word sequences are
13506 converted to phrase tests. The word
<quote>or
</quote> is understood
13507 as producing an OR operator, and a dash produces a NOT operator;
13508 other punctuation is ignored.
13509 This approximates the behavior of some common web search tools.
13512 <literal>websearch_to_tsquery('english', '
"fat rat" or cat dog')
</literal>
13513 <returnvalue>'fat'
<-
> 'rat' | 'cat'
& 'dog'
</returnvalue>
13518 <entry role=
"func_table_entry"><para role=
"func_signature">
13520 <primary>querytree
</primary>
13522 <function>querytree
</function> (
<type>tsquery
</type> )
13523 <returnvalue>text
</returnvalue>
13526 Produces a representation of the indexable portion of
13527 a
<type>tsquery
</type>. A result that is empty or
13528 just
<literal>T
</literal> indicates a non-indexable query.
13531 <literal>querytree('foo
& ! bar'::tsquery)
</literal>
13532 <returnvalue>'foo'
</returnvalue>
13537 <entry role=
"func_table_entry"><para role=
"func_signature">
13539 <primary>setweight
</primary>
13541 <function>setweight
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weight
</parameter> <type>"char"</type> )
13542 <returnvalue>tsvector
</returnvalue>
13545 Assigns the specified
<parameter>weight
</parameter> to each element
13546 of the
<parameter>vector
</parameter>.
13549 <literal>setweight('fat:
2,
4 cat:
3 rat:
5B'::tsvector, 'A')
</literal>
13550 <returnvalue>'cat':
3A 'fat':
2A,
4A 'rat':
5A
</returnvalue>
13555 <entry role=
"func_table_entry"><para role=
"func_signature">
13557 <primary>setweight
</primary>
13558 <secondary>setweight for specific lexeme(s)
</secondary>
13560 <function>setweight
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weight
</parameter> <type>"char"</type>,
<parameter>lexemes
</parameter> <type>text[]
</type> )
13561 <returnvalue>tsvector
</returnvalue>
13564 Assigns the specified
<parameter>weight
</parameter> to elements
13565 of the
<parameter>vector
</parameter> that are listed
13566 in
<parameter>lexemes
</parameter>.
13567 The strings in
<parameter>lexemes
</parameter> are taken as lexemes
13568 as-is, without further processing. Strings that do not match any
13569 lexeme in
<parameter>vector
</parameter> are ignored.
13572 <literal>setweight('fat:
2,
4 cat:
3 rat:
5,
6B'::tsvector, 'A', '{cat,rat}')
</literal>
13573 <returnvalue>'cat':
3A 'fat':
2,
4 'rat':
5A,
6A
</returnvalue>
13578 <entry role=
"func_table_entry"><para role=
"func_signature">
13580 <primary>strip
</primary>
13582 <function>strip
</function> (
<type>tsvector
</type> )
13583 <returnvalue>tsvector
</returnvalue>
13586 Removes positions and weights from the
<type>tsvector
</type>.
13589 <literal>strip('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13590 <returnvalue>'cat' 'fat' 'rat'
</returnvalue>
13595 <entry role=
"func_table_entry"><para role=
"func_signature">
13597 <primary>to_tsquery
</primary>
13599 <function>to_tsquery
</function> (
13600 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13601 <parameter>query
</parameter> <type>text
</type> )
13602 <returnvalue>tsquery
</returnvalue>
13605 Converts text to a
<type>tsquery
</type>, normalizing words according to
13606 the specified or default configuration. The words must be combined
13607 by valid
<type>tsquery
</type> operators.
13610 <literal>to_tsquery('english', 'The
& Fat
& Rats')
</literal>
13611 <returnvalue>'fat'
& 'rat'
</returnvalue>
13616 <entry role=
"func_table_entry"><para role=
"func_signature">
13618 <primary>to_tsvector
</primary>
13620 <function>to_tsvector
</function> (
13621 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13622 <parameter>document
</parameter> <type>text
</type> )
13623 <returnvalue>tsvector
</returnvalue>
13626 Converts text to a
<type>tsvector
</type>, normalizing words according
13627 to the specified or default configuration. Position information is
13628 included in the result.
13631 <literal>to_tsvector('english', 'The Fat Rats')
</literal>
13632 <returnvalue>'fat':
2 'rat':
3</returnvalue>
13637 <entry role=
"func_table_entry"><para role=
"func_signature">
13638 <function>to_tsvector
</function> (
13639 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13640 <parameter>document
</parameter> <type>json
</type> )
13641 <returnvalue>tsvector
</returnvalue>
13643 <para role=
"func_signature">
13644 <function>to_tsvector
</function> (
13645 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13646 <parameter>document
</parameter> <type>jsonb
</type> )
13647 <returnvalue>tsvector
</returnvalue>
13650 Converts each string value in the JSON document to
13651 a
<type>tsvector
</type>, normalizing words according to the specified
13652 or default configuration. The results are then concatenated in
13653 document order to produce the output. Position information is
13654 generated as though one stopword exists between each pair of string
13655 values. (Beware that
<quote>document order
</quote> of the fields of a
13656 JSON object is implementation-dependent when the input
13657 is
<type>jsonb
</type>; observe the difference in the examples.)
13660 <literal>to_tsvector('english', '{
"aa":
"The Fat Rats",
"b":
"dog"}'::json)
</literal>
13661 <returnvalue>'dog':
5 'fat':
2 'rat':
3</returnvalue>
13664 <literal>to_tsvector('english', '{
"aa":
"The Fat Rats",
"b":
"dog"}'::jsonb)
</literal>
13665 <returnvalue>'dog':
1 'fat':
4 'rat':
5</returnvalue>
13670 <entry role=
"func_table_entry"><para role=
"func_signature">
13672 <primary>json_to_tsvector
</primary>
13674 <function>json_to_tsvector
</function> (
13675 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13676 <parameter>document
</parameter> <type>json
</type>,
13677 <parameter>filter
</parameter> <type>jsonb
</type> )
13678 <returnvalue>tsvector
</returnvalue>
13680 <para role=
"func_signature">
13682 <primary>jsonb_to_tsvector
</primary>
13684 <function>jsonb_to_tsvector
</function> (
13685 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13686 <parameter>document
</parameter> <type>jsonb
</type>,
13687 <parameter>filter
</parameter> <type>jsonb
</type> )
13688 <returnvalue>tsvector
</returnvalue>
13691 Selects each item in the JSON document that is requested by
13692 the
<parameter>filter
</parameter> and converts each one to
13693 a
<type>tsvector
</type>, normalizing words according to the specified
13694 or default configuration. The results are then concatenated in
13695 document order to produce the output. Position information is
13696 generated as though one stopword exists between each pair of selected
13697 items. (Beware that
<quote>document order
</quote> of the fields of a
13698 JSON object is implementation-dependent when the input
13699 is
<type>jsonb
</type>.)
13700 The
<parameter>filter
</parameter> must be a
<type>jsonb
</type>
13701 array containing zero or more of these keywords:
13702 <literal>"string"</literal> (to include all string values),
13703 <literal>"numeric"</literal> (to include all numeric values),
13704 <literal>"boolean"</literal> (to include all boolean values),
13705 <literal>"key"</literal> (to include all keys), or
13706 <literal>"all"</literal> (to include all the above).
13707 As a special case, the
<parameter>filter
</parameter> can also be a
13708 simple JSON value that is one of these keywords.
13711 <literal>json_to_tsvector('english', '{
"a":
"The Fat Rats",
"b":
123}'::json, '[
"string",
"numeric"]')
</literal>
13712 <returnvalue>'
123':
5 'fat':
2 'rat':
3</returnvalue>
13715 <literal>json_to_tsvector('english', '{
"cat":
"The Fat Rats",
"dog":
123}'::json, '
"all"')
</literal>
13716 <returnvalue>'
123':
9 'cat':
1 'dog':
7 'fat':
4 'rat':
5</returnvalue>
13721 <entry role=
"func_table_entry"><para role=
"func_signature">
13723 <primary>ts_delete
</primary>
13725 <function>ts_delete
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>lexeme
</parameter> <type>text
</type> )
13726 <returnvalue>tsvector
</returnvalue>
13729 Removes any occurrence of the given
<parameter>lexeme
</parameter>
13730 from the
<parameter>vector
</parameter>.
13731 The
<parameter>lexeme
</parameter> string is treated as a lexeme as-is,
13732 without further processing.
13735 <literal>ts_delete('fat:
2,
4 cat:
3 rat:
5A'::tsvector, 'fat')
</literal>
13736 <returnvalue>'cat':
3 'rat':
5A
</returnvalue>
13741 <entry role=
"func_table_entry"><para role=
"func_signature">
13742 <function>ts_delete
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>lexemes
</parameter> <type>text[]
</type> )
13743 <returnvalue>tsvector
</returnvalue>
13746 Removes any occurrences of the lexemes
13747 in
<parameter>lexemes
</parameter>
13748 from the
<parameter>vector
</parameter>.
13749 The strings in
<parameter>lexemes
</parameter> are taken as lexemes
13750 as-is, without further processing. Strings that do not match any
13751 lexeme in
<parameter>vector
</parameter> are ignored.
13754 <literal>ts_delete('fat:
2,
4 cat:
3 rat:
5A'::tsvector, ARRAY['fat','rat'])
</literal>
13755 <returnvalue>'cat':
3</returnvalue>
13760 <entry role=
"func_table_entry"><para role=
"func_signature">
13762 <primary>ts_filter
</primary>
13764 <function>ts_filter
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weights
</parameter> <type>"char"[]
</type> )
13765 <returnvalue>tsvector
</returnvalue>
13768 Selects only elements with the given
<parameter>weights
</parameter>
13769 from the
<parameter>vector
</parameter>.
13772 <literal>ts_filter('fat:
2,
4 cat:
3b,
7c rat:
5A'::tsvector, '{a,b}')
</literal>
13773 <returnvalue>'cat':
3B 'rat':
5A
</returnvalue>
13778 <entry role=
"func_table_entry"><para role=
"func_signature">
13780 <primary>ts_headline
</primary>
13782 <function>ts_headline
</function> (
13783 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13784 <parameter>document
</parameter> <type>text
</type>,
13785 <parameter>query
</parameter> <type>tsquery
</type>
13786 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13787 <returnvalue>text
</returnvalue>
13790 Displays, in an abbreviated form, the match(es) for
13791 the
<parameter>query
</parameter> in
13792 the
<parameter>document
</parameter>, which must be raw text not
13793 a
<type>tsvector
</type>. Words in the document are normalized
13794 according to the specified or default configuration before matching to
13795 the query. Use of this function is discussed in
13796 <xref linkend=
"textsearch-headline"/>, which also describes the
13797 available
<parameter>options
</parameter>.
13800 <literal>ts_headline('The fat cat ate the rat.', 'cat')
</literal>
13801 <returnvalue>The fat
<b
>cat
</b
> ate the rat.
</returnvalue>
13806 <entry role=
"func_table_entry"><para role=
"func_signature">
13807 <function>ts_headline
</function> (
13808 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13809 <parameter>document
</parameter> <type>json
</type>,
13810 <parameter>query
</parameter> <type>tsquery
</type>
13811 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13812 <returnvalue>text
</returnvalue>
13814 <para role=
"func_signature">
13815 <function>ts_headline
</function> (
13816 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13817 <parameter>document
</parameter> <type>jsonb
</type>,
13818 <parameter>query
</parameter> <type>tsquery
</type>
13819 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13820 <returnvalue>text
</returnvalue>
13823 Displays, in an abbreviated form, match(es) for
13824 the
<parameter>query
</parameter> that occur in string values
13825 within the JSON
<parameter>document
</parameter>.
13826 See
<xref linkend=
"textsearch-headline"/> for more details.
13829 <literal>ts_headline('{
"cat":
"raining cats and dogs"}'::jsonb, 'cat')
</literal>
13830 <returnvalue>{
"cat":
"raining <b>cats</b> and dogs"}
</returnvalue>
13835 <entry role=
"func_table_entry"><para role=
"func_signature">
13837 <primary>ts_rank
</primary>
13839 <function>ts_rank
</function> (
13840 <optional> <parameter>weights
</parameter> <type>real[]
</type>,
</optional>
13841 <parameter>vector
</parameter> <type>tsvector
</type>,
13842 <parameter>query
</parameter> <type>tsquery
</type>
13843 <optional>,
<parameter>normalization
</parameter> <type>integer
</type> </optional> )
13844 <returnvalue>real
</returnvalue>
13847 Computes a score showing how well
13848 the
<parameter>vector
</parameter> matches
13849 the
<parameter>query
</parameter>. See
13850 <xref linkend=
"textsearch-ranking"/> for details.
13853 <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')
</literal>
13854 <returnvalue>0.06079271</returnvalue>
13859 <entry role=
"func_table_entry"><para role=
"func_signature">
13861 <primary>ts_rank_cd
</primary>
13863 <function>ts_rank_cd
</function> (
13864 <optional> <parameter>weights
</parameter> <type>real[]
</type>,
</optional>
13865 <parameter>vector
</parameter> <type>tsvector
</type>,
13866 <parameter>query
</parameter> <type>tsquery
</type>
13867 <optional>,
<parameter>normalization
</parameter> <type>integer
</type> </optional> )
13868 <returnvalue>real
</returnvalue>
13871 Computes a score showing how well
13872 the
<parameter>vector
</parameter> matches
13873 the
<parameter>query
</parameter>, using a cover density
13874 algorithm. See
<xref linkend=
"textsearch-ranking"/> for details.
13877 <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')
</literal>
13878 <returnvalue>0.1</returnvalue>
13883 <entry role=
"func_table_entry"><para role=
"func_signature">
13885 <primary>ts_rewrite
</primary>
13887 <function>ts_rewrite
</function> (
<parameter>query
</parameter> <type>tsquery
</type>,
13888 <parameter>target
</parameter> <type>tsquery
</type>,
13889 <parameter>substitute
</parameter> <type>tsquery
</type> )
13890 <returnvalue>tsquery
</returnvalue>
13893 Replaces occurrences of
<parameter>target
</parameter>
13894 with
<parameter>substitute
</parameter>
13895 within the
<parameter>query
</parameter>.
13896 See
<xref linkend=
"textsearch-query-rewriting"/> for details.
13899 <literal>ts_rewrite('a
& b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)
</literal>
13900 <returnvalue>'b'
& ( 'foo' | 'bar' )
</returnvalue>
13905 <entry role=
"func_table_entry"><para role=
"func_signature">
13906 <function>ts_rewrite
</function> (
<parameter>query
</parameter> <type>tsquery
</type>,
13907 <parameter>select
</parameter> <type>text
</type> )
13908 <returnvalue>tsquery
</returnvalue>
13911 Replaces portions of the
<parameter>query
</parameter> according to
13912 target(s) and substitute(s) obtained by executing
13913 a
<command>SELECT
</command> command.
13914 See
<xref linkend=
"textsearch-query-rewriting"/> for details.
13917 <literal>SELECT ts_rewrite('a
& b'::tsquery, 'SELECT t,s FROM aliases')
</literal>
13918 <returnvalue>'b'
& ( 'foo' | 'bar' )
</returnvalue>
13923 <entry role=
"func_table_entry"><para role=
"func_signature">
13925 <primary>tsquery_phrase
</primary>
13927 <function>tsquery_phrase
</function> (
<parameter>query1
</parameter> <type>tsquery
</type>,
<parameter>query2
</parameter> <type>tsquery
</type> )
13928 <returnvalue>tsquery
</returnvalue>
13931 Constructs a phrase query that searches
13932 for matches of
<parameter>query1
</parameter>
13933 and
<parameter>query2
</parameter> at successive lexemes (same
13934 as
<literal><-
></literal> operator).
13937 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))
</literal>
13938 <returnvalue>'fat'
<-
> 'cat'
</returnvalue>
13943 <entry role=
"func_table_entry"><para role=
"func_signature">
13944 <function>tsquery_phrase
</function> (
<parameter>query1
</parameter> <type>tsquery
</type>,
<parameter>query2
</parameter> <type>tsquery
</type>,
<parameter>distance
</parameter> <type>integer
</type> )
13945 <returnvalue>tsquery
</returnvalue>
13948 Constructs a phrase query that searches
13949 for matches of
<parameter>query1
</parameter> and
13950 <parameter>query2
</parameter> that occur exactly
13951 <parameter>distance
</parameter> lexemes apart.
13954 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'),
10)
</literal>
13955 <returnvalue>'fat'
<10> 'cat'
</returnvalue>
13960 <entry role=
"func_table_entry"><para role=
"func_signature">
13962 <primary>tsvector_to_array
</primary>
13964 <function>tsvector_to_array
</function> (
<type>tsvector
</type> )
13965 <returnvalue>text[]
</returnvalue>
13968 Converts a
<type>tsvector
</type> to an array of lexemes.
13971 <literal>tsvector_to_array('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13972 <returnvalue>{cat,fat,rat}
</returnvalue>
13977 <entry role=
"func_table_entry"><para role=
"func_signature">
13979 <primary>unnest
</primary>
13980 <secondary>for tsvector
</secondary>
13982 <function>unnest
</function> (
<type>tsvector
</type> )
13983 <returnvalue>setof record
</returnvalue>
13984 (
<parameter>lexeme
</parameter> <type>text
</type>,
13985 <parameter>positions
</parameter> <type>smallint[]
</type>,
13986 <parameter>weights
</parameter> <type>text
</type> )
13989 Expands a
<type>tsvector
</type> into a set of rows, one per lexeme.
13992 <literal>select * from unnest('cat:
3 fat:
2,
4 rat:
5A'::tsvector)
</literal>
13993 <returnvalue></returnvalue>
13995 lexeme | positions | weights
13996 --------+-----------+---------
13998 fat | {
2,
4} | {D,D}
14009 All the text search functions that accept an optional
<type>regconfig
</type>
14010 argument will use the configuration specified by
14011 <xref linkend=
"guc-default-text-search-config"/>
14012 when that argument is omitted.
14018 <xref linkend=
"textsearch-functions-debug-table"/>
14019 are listed separately because they are not usually used in everyday text
14020 searching operations. They are primarily helpful for development and
14021 debugging of new text search configurations.
14024 <table id=
"textsearch-functions-debug-table">
14025 <title>Text Search Debugging Functions
</title>
14029 <entry role=
"func_table_entry"><para role=
"func_signature">
14043 <entry role=
"func_table_entry"><para role=
"func_signature">
14045 <primary>ts_debug
</primary>
14047 <function>ts_debug
</function> (
14048 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
14049 <parameter>document
</parameter> <type>text
</type> )
14050 <returnvalue>setof record
</returnvalue>
14051 (
<parameter>alias
</parameter> <type>text
</type>,
14052 <parameter>description
</parameter> <type>text
</type>,
14053 <parameter>token
</parameter> <type>text
</type>,
14054 <parameter>dictionaries
</parameter> <type>regdictionary[]
</type>,
14055 <parameter>dictionary
</parameter> <type>regdictionary
</type>,
14056 <parameter>lexemes
</parameter> <type>text[]
</type> )
14059 Extracts and normalizes tokens from
14060 the
<parameter>document
</parameter> according to the specified or
14061 default text search configuration, and returns information about how
14062 each token was processed.
14063 See
<xref linkend=
"textsearch-configuration-testing"/> for details.
14066 <literal>ts_debug('english', 'The Brightest supernovaes')
</literal>
14067 <returnvalue>(asciiword,
"Word, all ASCII",The,{english_stem},english_stem,{}) ...
</returnvalue>
14072 <entry role=
"func_table_entry"><para role=
"func_signature">
14074 <primary>ts_lexize
</primary>
14076 <function>ts_lexize
</function> (
<parameter>dict
</parameter> <type>regdictionary
</type>,
<parameter>token
</parameter> <type>text
</type> )
14077 <returnvalue>text[]
</returnvalue>
14080 Returns an array of replacement lexemes if the input token is known to
14081 the dictionary, or an empty array if the token is known to the
14082 dictionary but it is a stop word, or NULL if it is not a known word.
14083 See
<xref linkend=
"textsearch-dictionary-testing"/> for details.
14086 <literal>ts_lexize('english_stem', 'stars')
</literal>
14087 <returnvalue>{star}
</returnvalue>
14092 <entry role=
"func_table_entry"><para role=
"func_signature">
14094 <primary>ts_parse
</primary>
14096 <function>ts_parse
</function> (
<parameter>parser_name
</parameter> <type>text
</type>,
14097 <parameter>document
</parameter> <type>text
</type> )
14098 <returnvalue>setof record
</returnvalue>
14099 (
<parameter>tokid
</parameter> <type>integer
</type>,
14100 <parameter>token
</parameter> <type>text
</type> )
14103 Extracts tokens from the
<parameter>document
</parameter> using the
14105 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14108 <literal>ts_parse('default', 'foo - bar')
</literal>
14109 <returnvalue>(
1,foo) ...
</returnvalue>
14114 <entry role=
"func_table_entry"><para role=
"func_signature">
14115 <function>ts_parse
</function> (
<parameter>parser_oid
</parameter> <type>oid
</type>,
14116 <parameter>document
</parameter> <type>text
</type> )
14117 <returnvalue>setof record
</returnvalue>
14118 (
<parameter>tokid
</parameter> <type>integer
</type>,
14119 <parameter>token
</parameter> <type>text
</type> )
14122 Extracts tokens from the
<parameter>document
</parameter> using a
14123 parser specified by OID.
14124 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14127 <literal>ts_parse(
3722, 'foo - bar')
</literal>
14128 <returnvalue>(
1,foo) ...
</returnvalue>
14133 <entry role=
"func_table_entry"><para role=
"func_signature">
14135 <primary>ts_token_type
</primary>
14137 <function>ts_token_type
</function> (
<parameter>parser_name
</parameter> <type>text
</type> )
14138 <returnvalue>setof record
</returnvalue>
14139 (
<parameter>tokid
</parameter> <type>integer
</type>,
14140 <parameter>alias
</parameter> <type>text
</type>,
14141 <parameter>description
</parameter> <type>text
</type> )
14144 Returns a table that describes each type of token the named parser can
14146 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14149 <literal>ts_token_type('default')
</literal>
14150 <returnvalue>(
1,asciiword,
"Word, all ASCII") ...
</returnvalue>
14155 <entry role=
"func_table_entry"><para role=
"func_signature">
14156 <function>ts_token_type
</function> (
<parameter>parser_oid
</parameter> <type>oid
</type> )
14157 <returnvalue>setof record
</returnvalue>
14158 (
<parameter>tokid
</parameter> <type>integer
</type>,
14159 <parameter>alias
</parameter> <type>text
</type>,
14160 <parameter>description
</parameter> <type>text
</type> )
14163 Returns a table that describes each type of token a parser specified
14164 by OID can recognize.
14165 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14168 <literal>ts_token_type(
3722)
</literal>
14169 <returnvalue>(
1,asciiword,
"Word, all ASCII") ...
</returnvalue>
14174 <entry role=
"func_table_entry"><para role=
"func_signature">
14176 <primary>ts_stat
</primary>
14178 <function>ts_stat
</function> (
<parameter>sqlquery
</parameter> <type>text
</type>
14179 <optional>,
<parameter>weights
</parameter> <type>text
</type> </optional> )
14180 <returnvalue>setof record
</returnvalue>
14181 (
<parameter>word
</parameter> <type>text
</type>,
14182 <parameter>ndoc
</parameter> <type>integer
</type>,
14183 <parameter>nentry
</parameter> <type>integer
</type> )
14186 Executes the
<parameter>sqlquery
</parameter>, which must return a
14187 single
<type>tsvector
</type> column, and returns statistics about each
14188 distinct lexeme contained in the data.
14189 See
<xref linkend=
"textsearch-statistics"/> for details.
14192 <literal>ts_stat('SELECT vector FROM apod')
</literal>
14193 <returnvalue>(foo,
10,
15) ...
</returnvalue>
14202 <sect1 id=
"functions-uuid">
14203 <title>UUID Functions
</title>
14205 <indexterm zone=
"datatype-uuid">
14206 <primary>UUID
</primary>
14207 <secondary>generating
</secondary>
14211 <primary>gen_random_uuid
</primary>
14215 <primary>uuid_extract_timestamp
</primary>
14219 <primary>uuid_extract_version
</primary>
14223 <productname>PostgreSQL
</productname> includes one function to generate a UUID:
14225 <function>gen_random_uuid
</function> ()
<returnvalue>uuid
</returnvalue>
14227 This function returns a version
4 (random) UUID. This is the most commonly
14228 used type of UUID and is appropriate for most applications.
14232 The
<xref linkend=
"uuid-ossp"/> module provides additional functions that
14233 implement other standard algorithms for generating UUIDs.
14237 There are also functions to extract data from UUIDs:
14239 <function>uuid_extract_timestamp
</function> (uuid)
<returnvalue>timestamp with time zone
</returnvalue>
14241 This function extracts a
<type>timestamp with time zone
</type> from UUID
14242 version
1. For other versions, this function returns null. Note that the
14243 extracted timestamp is not necessarily exactly equal to the time the UUID
14244 was generated; this depends on the implementation that generated the UUID.
14249 <function>uuid_extract_version
</function> (uuid)
<returnvalue>smallint
</returnvalue>
14251 This function extracts the version from a UUID of the variant described by
14252 <ulink url=
"https://datatracker.ietf.org/doc/html/rfc4122">RFC
4122</ulink>. For
14253 other variants, this function returns null. For example, for a UUID
14254 generated by
<function>gen_random_uuid
</function>, this function will
14259 <productname>PostgreSQL
</productname> also provides the usual comparison
14260 operators shown in
<xref linkend=
"functions-comparison-op-table"/> for
14265 <sect1 id=
"functions-xml">
14267 <title>XML Functions
</title>
14270 <primary>XML Functions
</primary>
14274 The functions and function-like expressions described in this
14275 section operate on values of type
<type>xml
</type>. See
<xref
14276 linkend=
"datatype-xml"/> for information about the
<type>xml
</type>
14277 type. The function-like expressions
<function>xmlparse
</function>
14278 and
<function>xmlserialize
</function> for converting to and from
14279 type
<type>xml
</type> are documented there, not in this section.
14283 Use of most of these functions
14284 requires
<productname>PostgreSQL
</productname> to have been built
14285 with
<command>configure --with-libxml
</command>.
14288 <sect2 id=
"functions-producing-xml">
14289 <title>Producing XML Content
</title>
14292 A set of functions and function-like expressions is available for
14293 producing XML content from SQL data. As such, they are
14294 particularly suitable for formatting query results into XML
14295 documents for processing in client applications.
14298 <sect3 id=
"functions-producing-xml-xmltext">
14299 <title><literal>xmltext
</literal></title>
14302 <primary>xmltext
</primary>
14306 <function>xmltext
</function> (
<type>text
</type> )
<returnvalue>xml
</returnvalue>
14310 The function
<function>xmltext
</function> returns an XML value with a single
14311 text node containing the input argument as its content. Predefined entities
14312 like ampersand (
<literal><![CDATA[&]]
></literal>), left and right angle brackets
14313 (
<literal><![CDATA[<
>]]
></literal>), and quotation marks (
<literal><![CDATA[
""]]
></literal>)
14320 SELECT xmltext('< foo & bar
>');
14322 -------------------------
14323 < foo
& bar
>
14328 <sect3 id=
"functions-producing-xml-xmlcomment">
14329 <title><literal>xmlcomment
</literal></title>
14332 <primary>xmlcomment
</primary>
14336 <function>xmlcomment
</function> (
<type>text
</type> )
<returnvalue>xml
</returnvalue>
14340 The function
<function>xmlcomment
</function> creates an XML value
14341 containing an XML comment with the specified text as content.
14342 The text cannot contain
<quote><literal>--
</literal></quote> or end with a
14343 <quote><literal>-
</literal></quote>, otherwise the resulting construct
14344 would not be a valid XML comment.
14345 If the argument is null, the result is null.
14351 SELECT xmlcomment('hello');
14360 <sect3 id=
"functions-producing-xml-xmlconcat">
14361 <title><literal>xmlconcat
</literal></title>
14364 <primary>xmlconcat
</primary>
14368 <function>xmlconcat
</function> (
<type>xml
</type> <optional>, ...
</optional> )
<returnvalue>xml
</returnvalue>
14372 The function
<function>xmlconcat
</function> concatenates a list
14373 of individual XML values to create a single value containing an
14374 XML content fragment. Null values are omitted; the result is
14375 only null if there are no nonnull arguments.
14381 SELECT xmlconcat('
<abc/>', '
<bar>foo
</bar>');
14384 ----------------------
14385 <abc/><bar>foo
</bar>
14390 XML declarations, if present, are combined as follows. If all
14391 argument values have the same XML version declaration, that
14392 version is used in the result, else no version is used. If all
14393 argument values have the standalone declaration value
14394 <quote>yes
</quote>, then that value is used in the result. If
14395 all argument values have a standalone declaration value and at
14396 least one is
<quote>no
</quote>, then that is used in the result.
14397 Else the result will have no standalone declaration. If the
14398 result is determined to require a standalone declaration but no
14399 version declaration, a version declaration with version
1.0 will
14400 be used because XML requires an XML declaration to contain a
14401 version declaration. Encoding declarations are ignored and
14402 removed in all cases.
14408 SELECT xmlconcat('
<?xml version=
"1.1"?><foo/>', '
<?xml version=
"1.1" standalone=
"no"?><bar/>');
14411 -----------------------------------
14412 <?xml version=
"1.1"?><foo/><bar/>
14417 <sect3 id=
"functions-producing-xml-xmlelement">
14418 <title><literal>xmlelement
</literal></title>
14421 <primary>xmlelement
</primary>
14425 <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>
14429 The
<function>xmlelement
</function> expression produces an XML
14430 element with the given name, attributes, and content.
14431 The
<replaceable>name
</replaceable>
14432 and
<replaceable>attname
</replaceable> items shown in the syntax are
14433 simple identifiers, not values. The
<replaceable>attvalue
</replaceable>
14434 and
<replaceable>content
</replaceable> items are expressions, which can
14435 yield any
<productname>PostgreSQL
</productname> data type. The
14436 argument(s) within
<literal>XMLATTRIBUTES
</literal> generate attributes
14437 of the XML element; the
<replaceable>content
</replaceable> value(s) are
14438 concatenated to form its content.
14444 SELECT xmlelement(name foo);
14450 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
14456 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
14459 -------------------------------------
14460 <foo bar=
"2007-01-26">content
</foo>
14465 Element and attribute names that are not valid XML names are
14466 escaped by replacing the offending characters by the sequence
14467 <literal>_x
<replaceable>HHHH
</replaceable>_
</literal>, where
14468 <replaceable>HHHH
</replaceable> is the character's Unicode
14469 codepoint in hexadecimal notation. For example:
14471 SELECT xmlelement(name
"foo$bar", xmlattributes('xyz' as
"a&b"));
14474 ----------------------------------
14475 <foo_x0024_bar a_x0026_b=
"xyz"/>
14480 An explicit attribute name need not be specified if the attribute
14481 value is a column reference, in which case the column's name will
14482 be used as the attribute name by default. In other cases, the
14483 attribute must be given an explicit name. So this example is
14486 CREATE TABLE test (a xml, b xml);
14487 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
14491 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
14492 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
14497 Element content, if specified, will be formatted according to
14498 its data type. If the content is itself of type
<type>xml
</type>,
14499 complex XML documents can be constructed. For example:
14501 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
14502 xmlelement(name abc),
14503 xmlcomment('test'),
14504 xmlelement(name xyz));
14507 ----------------------------------------------
14508 <foo bar=
"xyz"><abc/><!--test--><xyz/></foo>
14511 Content of other types will be formatted into valid XML character
14512 data. This means in particular that the characters
<,
>,
14513 and
& will be converted to entities. Binary data (data type
14514 <type>bytea
</type>) will be represented in base64 or hex
14515 encoding, depending on the setting of the configuration parameter
14516 <xref linkend=
"guc-xmlbinary"/>. The particular behavior for
14517 individual data types is expected to evolve in order to align the
14518 PostgreSQL mappings with those specified in SQL:
2006 and later,
14519 as discussed in
<xref linkend=
"functions-xml-limits-casts"/>.
14523 <sect3 id=
"functions-producing-xml-xmlforest">
14524 <title><literal>xmlforest
</literal></title>
14527 <primary>xmlforest
</primary>
14531 <function>xmlforest
</function> (
<replaceable>content
</replaceable> <optional> <literal>AS
</literal> <replaceable>name
</replaceable> </optional> <optional>, ...
</optional> )
<returnvalue>xml
</returnvalue>
14535 The
<function>xmlforest
</function> expression produces an XML
14536 forest (sequence) of elements using the given names and content.
14537 As for
<function>xmlelement
</function>,
14538 each
<replaceable>name
</replaceable> must be a simple identifier, while
14539 the
<replaceable>content
</replaceable> expressions can have any data
14546 SELECT xmlforest('abc' AS foo,
123 AS bar);
14549 ------------------------------
14550 <foo
>abc
</foo
><bar
>123</bar
>
14553 SELECT xmlforest(table_name, column_name)
14554 FROM information_schema.columns
14555 WHERE table_schema = 'pg_catalog';
14558 ------------------------------------
&zwsp;-----------------------------------
14559 <table_name
>pg_authid
</table_name
>&zwsp;<column_name
>rolname
</column_name
>
14560 <table_name
>pg_authid
</table_name
>&zwsp;<column_name
>rolsuper
</column_name
>
14564 As seen in the second example, the element name can be omitted if
14565 the content value is a column reference, in which case the column
14566 name is used by default. Otherwise, a name must be specified.
14570 Element names that are not valid XML names are escaped as shown
14571 for
<function>xmlelement
</function> above. Similarly, content
14572 data is escaped to make valid XML content, unless it is already
14573 of type
<type>xml
</type>.
14577 Note that XML forests are not valid XML documents if they consist
14578 of more than one element, so it might be useful to wrap
14579 <function>xmlforest
</function> expressions in
14580 <function>xmlelement
</function>.
14584 <sect3 id=
"functions-producing-xml-xmlpi">
14585 <title><literal>xmlpi
</literal></title>
14588 <primary>xmlpi
</primary>
14592 <function>xmlpi
</function> (
<literal>NAME
</literal> <replaceable>name
</replaceable> <optional>,
<replaceable>content
</replaceable> </optional> )
<returnvalue>xml
</returnvalue>
14596 The
<function>xmlpi
</function> expression creates an XML
14597 processing instruction.
14598 As for
<function>xmlelement
</function>,
14599 the
<replaceable>name
</replaceable> must be a simple identifier, while
14600 the
<replaceable>content
</replaceable> expression can have any data type.
14601 The
<replaceable>content
</replaceable>, if present, must not contain the
14602 character sequence
<literal>?
></literal>.
14608 SELECT xmlpi(name php, 'echo
"hello world";');
14611 -----------------------------
14612 <?php echo
"hello world";
?>
14617 <sect3 id=
"functions-producing-xml-xmlroot">
14618 <title><literal>xmlroot
</literal></title>
14621 <primary>xmlroot
</primary>
14625 <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>
14629 The
<function>xmlroot
</function> expression alters the properties
14630 of the root node of an XML value. If a version is specified,
14631 it replaces the value in the root node's version declaration; if a
14632 standalone setting is specified, it replaces the value in the
14633 root node's standalone declaration.
14638 SELECT xmlroot(xmlparse(document '
<?xml version=
"1.1"?><content>abc
</content>'),
14639 version '
1.0', standalone yes);
14642 ----------------------------------------
14643 <?xml version=
"1.0" standalone=
"yes"?>
14644 <content>abc
</content>
14649 <sect3 id=
"functions-xml-xmlagg">
14650 <title><literal>xmlagg
</literal></title>
14653 <primary>xmlagg
</primary>
14657 <function>xmlagg
</function> (
<type>xml
</type> )
<returnvalue>xml
</returnvalue>
14661 The function
<function>xmlagg
</function> is, unlike the other
14662 functions described here, an aggregate function. It concatenates the
14663 input values to the aggregate function call,
14664 much like
<function>xmlconcat
</function> does, except that concatenation
14665 occurs across rows rather than across expressions in a single row.
14666 See
<xref linkend=
"functions-aggregate"/> for additional information
14667 about aggregate functions.
14673 CREATE TABLE test (y int, x xml);
14674 INSERT INTO test VALUES (
1, '
<foo>abc
</foo>');
14675 INSERT INTO test VALUES (
2, '
<bar/>');
14676 SELECT xmlagg(x) FROM test;
14678 ----------------------
14679 <foo>abc
</foo><bar/>
14684 To determine the order of the concatenation, an
<literal>ORDER BY
</literal>
14685 clause may be added to the aggregate call as described in
14686 <xref linkend=
"syntax-aggregates"/>. For example:
14689 SELECT xmlagg(x ORDER BY y DESC) FROM test;
14691 ----------------------
14692 <bar/><foo>abc
</foo>
14697 The following non-standard approach used to be recommended
14698 in previous versions, and may still be useful in specific
14702 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
14704 ----------------------
14705 <bar/><foo>abc
</foo>
14711 <sect2 id=
"functions-xml-predicates">
14712 <title>XML Predicates
</title>
14715 The expressions described in this section check properties
14716 of
<type>xml
</type> values.
14719 <sect3 id=
"functions-producing-xml-is-document">
14720 <title><literal>IS DOCUMENT
</literal></title>
14723 <primary>IS DOCUMENT
</primary>
14727 <type>xml
</type> <literal>IS DOCUMENT
</literal> <returnvalue>boolean
</returnvalue>
14731 The expression
<literal>IS DOCUMENT
</literal> returns true if the
14732 argument XML value is a proper XML document, false if it is not
14733 (that is, it is a content fragment), or null if the argument is
14734 null. See
<xref linkend=
"datatype-xml"/> about the difference
14735 between documents and content fragments.
14739 <sect3 id=
"functions-producing-xml-is-not-document">
14740 <title><literal>IS NOT DOCUMENT
</literal></title>
14743 <primary>IS NOT DOCUMENT
</primary>
14747 <type>xml
</type> <literal>IS NOT DOCUMENT
</literal> <returnvalue>boolean
</returnvalue>
14751 The expression
<literal>IS NOT DOCUMENT
</literal> returns false if the
14752 argument XML value is a proper XML document, true if it is not (that is,
14753 it is a content fragment), or null if the argument is null.
14757 <sect3 id=
"xml-exists">
14758 <title><literal>XMLEXISTS
</literal></title>
14761 <primary>XMLEXISTS
</primary>
14765 <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>
14769 The function
<function>xmlexists
</function> evaluates an XPath
1.0
14770 expression (the first argument), with the passed XML value as its context
14771 item. The function returns false if the result of that evaluation
14772 yields an empty node-set, true if it yields any other value. The
14773 function returns null if any argument is null. A nonnull value
14774 passed as the context item must be an XML document, not a content
14775 fragment or any non-XML value.
14781 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '
<towns><town>Toronto
</town><town>Ottawa
</town></towns>');
14791 The
<literal>BY REF
</literal> and
<literal>BY VALUE
</literal> clauses
14792 are accepted in
<productname>PostgreSQL
</productname>, but are ignored,
14793 as discussed in
<xref linkend=
"functions-xml-limits-postgresql"/>.
14797 In the SQL standard, the
<function>xmlexists
</function> function
14798 evaluates an expression in the XML Query language,
14799 but
<productname>PostgreSQL
</productname> allows only an XPath
1.0
14800 expression, as discussed in
14801 <xref linkend=
"functions-xml-limits-xpath1"/>.
14805 <sect3 id=
"xml-is-well-formed">
14806 <title><literal>xml_is_well_formed
</literal></title>
14809 <primary>xml_is_well_formed
</primary>
14813 <primary>xml_is_well_formed_document
</primary>
14817 <primary>xml_is_well_formed_content
</primary>
14821 <function>xml_is_well_formed
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14822 <function>xml_is_well_formed_document
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14823 <function>xml_is_well_formed_content
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14827 These functions check whether a
<type>text
</type> string represents
14828 well-formed XML, returning a Boolean result.
14829 <function>xml_is_well_formed_document
</function> checks for a well-formed
14830 document, while
<function>xml_is_well_formed_content
</function> checks
14831 for well-formed content.
<function>xml_is_well_formed
</function> does
14832 the former if the
<xref linkend=
"guc-xmloption"/> configuration
14833 parameter is set to
<literal>DOCUMENT
</literal>, or the latter if it is set to
14834 <literal>CONTENT
</literal>. This means that
14835 <function>xml_is_well_formed
</function> is useful for seeing whether
14836 a simple cast to type
<type>xml
</type> will succeed, whereas the other two
14837 functions are useful for seeing whether the corresponding variants of
14838 <function>XMLPARSE
</function> will succeed.
14845 SET xmloption TO DOCUMENT;
14846 SELECT xml_is_well_formed('<
>');
14848 --------------------
14852 SELECT xml_is_well_formed('
<abc/>');
14854 --------------------
14858 SET xmloption TO CONTENT;
14859 SELECT xml_is_well_formed('abc');
14861 --------------------
14865 SELECT xml_is_well_formed_document('
<pg:foo xmlns:
pg=
"http://postgresql.org/stuff">bar
</pg:foo>');
14866 xml_is_well_formed_document
14867 -----------------------------
14871 SELECT xml_is_well_formed_document('
<pg:foo xmlns:
pg=
"http://postgresql.org/stuff">bar
</my:foo>');
14872 xml_is_well_formed_document
14873 -----------------------------
14878 The last example shows that the checks include whether
14879 namespaces are correctly matched.
14884 <sect2 id=
"functions-xml-processing">
14885 <title>Processing XML
</title>
14888 To process values of data type
<type>xml
</type>, PostgreSQL offers
14889 the functions
<function>xpath
</function> and
14890 <function>xpath_exists
</function>, which evaluate XPath
1.0
14891 expressions, and the
<function>XMLTABLE
</function>
14895 <sect3 id=
"functions-xml-processing-xpath">
14896 <title><literal>xpath
</literal></title>
14899 <primary>XPath
</primary>
14903 <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>
14907 The function
<function>xpath
</function> evaluates the XPath
1.0
14908 expression
<parameter>xpath
</parameter> (given as text)
14909 against the XML value
14910 <parameter>xml
</parameter>. It returns an array of XML values
14911 corresponding to the node-set produced by the XPath expression.
14912 If the XPath expression returns a scalar value rather than a node-set,
14913 a single-element array is returned.
14917 The second argument must be a well formed XML document. In particular,
14918 it must have a single root node element.
14922 The optional third argument of the function is an array of namespace
14923 mappings. This array should be a two-dimensional
<type>text
</type> array with
14924 the length of the second axis being equal to
2 (i.e., it should be an
14925 array of arrays, each of which consists of exactly
2 elements).
14926 The first element of each array entry is the namespace name (alias), the
14927 second the namespace URI. It is not required that aliases provided in
14928 this array be the same as those being used in the XML document itself (in
14929 other words, both in the XML document and in the
<function>xpath
</function>
14930 function context, aliases are
<emphasis>local
</emphasis>).
14936 SELECT xpath('/my:a/text()', '
<my:a xmlns:
my=
"http://example.com">test
</my:a>',
14937 ARRAY[ARRAY['my', 'http://example.com']]);
14947 To deal with default (anonymous) namespaces, do something like this:
14949 SELECT xpath('//mydefns:b/text()', '
<a xmlns=
"http://example.com"><b>test
</b></a>',
14950 ARRAY[ARRAY['mydefns', 'http://example.com']]);
14960 <sect3 id=
"functions-xml-processing-xpath-exists">
14961 <title><literal>xpath_exists
</literal></title>
14964 <primary>xpath_exists
</primary>
14968 <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>
14972 The function
<function>xpath_exists
</function> is a specialized form
14973 of the
<function>xpath
</function> function. Instead of returning the
14974 individual XML values that satisfy the XPath
1.0 expression, this function
14975 returns a Boolean indicating whether the query was satisfied or not
14976 (specifically, whether it produced any value other than an empty node-set).
14977 This function is equivalent to the
<literal>XMLEXISTS
</literal> predicate,
14978 except that it also offers support for a namespace mapping argument.
14984 SELECT xpath_exists('/my:a/text()', '
<my:a xmlns:
my=
"http://example.com">test
</my:a>',
14985 ARRAY[ARRAY['my', 'http://example.com']]);
14995 <sect3 id=
"functions-xml-processing-xmltable">
14996 <title><literal>xmltable
</literal></title>
14999 <primary>xmltable
</primary>
15002 <indexterm zone=
"functions-xml-processing-xmltable">
15003 <primary>table function
</primary>
15004 <secondary>XMLTABLE
</secondary>
15008 <function>XMLTABLE
</function> (
15009 <optional> <literal>XMLNAMESPACES
</literal> (
<replaceable>namespace_uri
</replaceable> <literal>AS
</literal> <replaceable>namespace_name
</replaceable> <optional>, ...
</optional> ),
</optional>
15010 <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>
15011 <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>
15012 |
<literal>FOR ORDINALITY
</literal> }
15013 <optional>, ...
</optional>
15014 )
<returnvalue>setof record
</returnvalue>
15018 The
<function>xmltable
</function> expression produces a table based
15019 on an XML value, an XPath filter to extract rows, and a
15020 set of column definitions.
15021 Although it syntactically resembles a function, it can only appear
15022 as a table in a query's
<literal>FROM
</literal> clause.
15026 The optional
<literal>XMLNAMESPACES
</literal> clause gives a
15027 comma-separated list of namespace definitions, where
15028 each
<replaceable>namespace_uri
</replaceable> is a
<type>text
</type>
15029 expression and each
<replaceable>namespace_name
</replaceable> is a simple
15030 identifier. It specifies the XML namespaces used in the document and
15031 their aliases. A default namespace specification is not currently
15036 The required
<replaceable>row_expression
</replaceable> argument is an
15037 XPath
1.0 expression (given as
<type>text
</type>) that is evaluated,
15038 passing the XML value
<replaceable>document_expression
</replaceable> as
15039 its context item, to obtain a set of XML nodes. These nodes are what
15040 <function>xmltable
</function> transforms into output rows. No rows
15041 will be produced if the
<replaceable>document_expression
</replaceable>
15042 is null, nor if the
<replaceable>row_expression
</replaceable> produces
15043 an empty node-set or any value other than a node-set.
15047 <replaceable>document_expression
</replaceable> provides the context
15048 item for the
<replaceable>row_expression
</replaceable>. It must be a
15049 well-formed XML document; fragments/forests are not accepted.
15050 The
<literal>BY REF
</literal> and
<literal>BY VALUE
</literal> clauses
15051 are accepted but ignored, as discussed in
15052 <xref linkend=
"functions-xml-limits-postgresql"/>.
15056 In the SQL standard, the
<function>xmltable
</function> function
15057 evaluates expressions in the XML Query language,
15058 but
<productname>PostgreSQL
</productname> allows only XPath
1.0
15059 expressions, as discussed in
15060 <xref linkend=
"functions-xml-limits-xpath1"/>.
15064 The required
<literal>COLUMNS
</literal> clause specifies the
15065 column(s) that will be produced in the output table.
15066 See the syntax summary above for the format.
15067 A name is required for each column, as is a data type
15068 (unless
<literal>FOR ORDINALITY
</literal> is specified, in which case
15069 type
<type>integer
</type> is implicit). The path, default and
15070 nullability clauses are optional.
15074 A column marked
<literal>FOR ORDINALITY
</literal> will be populated
15075 with row numbers, starting with
1, in the order of nodes retrieved from
15076 the
<replaceable>row_expression
</replaceable>'s result node-set.
15077 At most one column may be marked
<literal>FOR ORDINALITY
</literal>.
15082 XPath
1.0 does not specify an order for nodes in a node-set, so code
15083 that relies on a particular order of the results will be
15084 implementation-dependent. Details can be found in
15085 <xref linkend=
"xml-xpath-1-specifics"/>.
15090 The
<replaceable>column_expression
</replaceable> for a column is an
15091 XPath
1.0 expression that is evaluated for each row, with the current
15092 node from the
<replaceable>row_expression
</replaceable> result as its
15093 context item, to find the value of the column. If
15094 no
<replaceable>column_expression
</replaceable> is given, then the
15095 column name is used as an implicit path.
15099 If a column's XPath expression returns a non-XML value (which is limited
15100 to string, boolean, or double in XPath
1.0) and the column has a
15101 PostgreSQL type other than
<type>xml
</type>, the column will be set
15102 as if by assigning the value's string representation to the PostgreSQL
15103 type. (If the value is a boolean, its string representation is taken
15104 to be
<literal>1</literal> or
<literal>0</literal> if the output
15105 column's type category is numeric, otherwise
<literal>true
</literal> or
15106 <literal>false
</literal>.)
15110 If a column's XPath expression returns a non-empty set of XML nodes
15111 and the column's PostgreSQL type is
<type>xml
</type>, the column will
15112 be assigned the expression result exactly, if it is of document or
15116 A result containing more than one element node at the top level, or
15117 non-whitespace text outside of an element, is an example of content form.
15118 An XPath result can be of neither form, for example if it returns an
15119 attribute node selected from the element that contains it. Such a result
15120 will be put into content form with each such disallowed node replaced by
15121 its string value, as defined for the XPath
1.0
15122 <function>string
</function> function.
15128 A non-XML result assigned to an
<type>xml
</type> output column produces
15129 content, a single text node with the string value of the result.
15130 An XML result assigned to a column of any other type may not have more than
15131 one node, or an error is raised. If there is exactly one node, the column
15132 will be set as if by assigning the node's string
15133 value (as defined for the XPath
1.0 <function>string
</function> function)
15134 to the PostgreSQL type.
15138 The string value of an XML element is the concatenation, in document order,
15139 of all text nodes contained in that element and its descendants. The string
15140 value of an element with no descendant text nodes is an
15141 empty string (not
<literal>NULL
</literal>).
15142 Any
<literal>xsi:nil
</literal> attributes are ignored.
15143 Note that the whitespace-only
<literal>text()
</literal> node between two non-text
15144 elements is preserved, and that leading whitespace on a
<literal>text()
</literal>
15145 node is not flattened.
15146 The XPath
1.0 <function>string
</function> function may be consulted for the
15147 rules defining the string value of other XML node types and non-XML values.
15151 The conversion rules presented here are not exactly those of the SQL
15152 standard, as discussed in
<xref linkend=
"functions-xml-limits-casts"/>.
15156 If the path expression returns an empty node-set
15157 (typically, when it does not match)
15158 for a given row, the column will be set to
<literal>NULL
</literal>, unless
15159 a
<replaceable>default_expression
</replaceable> is specified; then the
15160 value resulting from evaluating that expression is used.
15164 A
<replaceable>default_expression
</replaceable>, rather than being
15165 evaluated immediately when
<function>xmltable
</function> is called,
15166 is evaluated each time a default is needed for the column.
15167 If the expression qualifies as stable or immutable, the repeat
15168 evaluation may be skipped.
15169 This means that you can usefully use volatile functions like
15170 <function>nextval
</function> in
15171 <replaceable>default_expression
</replaceable>.
15175 Columns may be marked
<literal>NOT NULL
</literal>. If the
15176 <replaceable>column_expression
</replaceable> for a
<literal>NOT
15177 NULL
</literal> column does not match anything and there is
15178 no
<literal>DEFAULT
</literal> or
15179 the
<replaceable>default_expression
</replaceable> also evaluates to null,
15180 an error is reported.
15186 CREATE TABLE xmldata AS SELECT
15190 <COUNTRY_ID>AU
</COUNTRY_ID>
15191 <COUNTRY_NAME>Australia
</COUNTRY_NAME>
15194 <COUNTRY_ID>JP
</COUNTRY_ID>
15195 <COUNTRY_NAME>Japan
</COUNTRY_NAME>
15196 <PREMIER_NAME>Shinzo Abe
</PREMIER_NAME>
15197 <SIZE unit=
"sq_mi">145935</SIZE>
15200 <COUNTRY_ID>SG
</COUNTRY_ID>
15201 <COUNTRY_NAME>Singapore
</COUNTRY_NAME>
15202 <SIZE unit=
"sq_km">697</SIZE>
15209 XMLTABLE('//ROWS/ROW'
15211 COLUMNS id int PATH '@id',
15212 ordinality FOR ORDINALITY,
15213 "COUNTRY_NAME" text,
15214 country_id text PATH 'COUNTRY_ID',
15215 size_sq_km float PATH 'SIZE[@unit =
"sq_km"]',
15216 size_other text PATH
15217 'concat(SIZE[@unit!=
"sq_km"],
" ", SIZE[@unit!=
"sq_km"]/@unit)',
15218 premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified');
15220 id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
15221 ----+------------+--------------+------------+------------+--------------+---------------
15222 1 |
1 | Australia | AU | | | not specified
15223 5 |
2 | Japan | JP | |
145935 sq_mi | Shinzo Abe
15224 6 |
3 | Singapore | SG |
697 | | not specified
15227 The following example shows concatenation of multiple text() nodes,
15228 usage of the column name as XPath filter, and the treatment of whitespace,
15229 XML comments and processing instructions:
15232 CREATE TABLE xmlelements AS SELECT
15235 <element> Hello
<!-- xyxxz -->2a2
<?aaaaa?> <!--x--> bbb
<x>xxx
</x>CC
</element>
15240 FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
15242 -------------------------
15248 The following example illustrates how
15249 the
<literal>XMLNAMESPACES
</literal> clause can be used to specify
15250 a list of namespaces
15251 used in the XML document as well as in the XPath expressions:
15254 WITH xmldata(data) AS (VALUES ('
15255 <example xmlns=
"http://example.com/myns" xmlns:
B=
"http://example.com/b">
15256 <item foo=
"1" B:
bar=
"2"/>
15257 <item foo=
"3" B:
bar=
"4"/>
15258 <item foo=
"4" B:
bar=
"5"/>
15262 FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
15263 'http://example.com/b' AS
"B"),
15264 '/x:example/x:item'
15265 PASSING (SELECT data FROM xmldata)
15266 COLUMNS foo int PATH '@foo',
15267 bar int PATH '@B:bar');
15279 <sect2 id=
"functions-xml-mapping">
15280 <title>Mapping Tables to XML
</title>
15282 <indexterm zone=
"functions-xml-mapping">
15283 <primary>XML export
</primary>
15287 The following functions map the contents of relational tables to
15288 XML values. They can be thought of as XML export functionality:
15290 <function>table_to_xml
</function> (
<parameter>table
</parameter> <type>regclass
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15291 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15292 <function>query_to_xml
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15293 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15294 <function>cursor_to_xml
</function> (
<parameter>cursor
</parameter> <type>refcursor
</type>,
<parameter>count
</parameter> <type>integer
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15295 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15300 <function>table_to_xml
</function> maps the content of the named
15301 table, passed as parameter
<parameter>table
</parameter>. The
15302 <type>regclass
</type> type accepts strings identifying tables using the
15303 usual notation, including optional schema qualification and
15304 double quotes (see
<xref linkend=
"datatype-oid"/> for details).
15305 <function>query_to_xml
</function> executes the
15306 query whose text is passed as parameter
15307 <parameter>query
</parameter> and maps the result set.
15308 <function>cursor_to_xml
</function> fetches the indicated number of
15309 rows from the cursor specified by the parameter
15310 <parameter>cursor
</parameter>. This variant is recommended if
15311 large tables have to be mapped, because the result value is built
15312 up in memory by each function.
15316 If
<parameter>tableforest
</parameter> is false, then the resulting
15317 XML document looks like this:
15321 <columnname1>data
</columnname1>
15322 <columnname2>data
</columnname2>
15333 If
<parameter>tableforest
</parameter> is true, the result is an
15334 XML content fragment that looks like this:
15337 <columnname1>data
</columnname1>
15338 <columnname2>data
</columnname2>
15348 If no table name is available, that is, when mapping a query or a
15349 cursor, the string
<literal>table
</literal> is used in the first
15350 format,
<literal>row
</literal> in the second format.
15354 The choice between these formats is up to the user. The first
15355 format is a proper XML document, which will be important in many
15356 applications. The second format tends to be more useful in the
15357 <function>cursor_to_xml
</function> function if the result values are to be
15358 reassembled into one document later on. The functions for
15359 producing XML content discussed above, in particular
15360 <function>xmlelement
</function>, can be used to alter the results
15365 The data values are mapped in the same way as described for the
15366 function
<function>xmlelement
</function> above.
15370 The parameter
<parameter>nulls
</parameter> determines whether null
15371 values should be included in the output. If true, null values in
15372 columns are represented as:
15374 <columnname xsi:
nil=
"true"/>
15376 where
<literal>xsi
</literal> is the XML namespace prefix for XML
15377 Schema Instance. An appropriate namespace declaration will be
15378 added to the result value. If false, columns containing null
15379 values are simply omitted from the output.
15383 The parameter
<parameter>targetns
</parameter> specifies the
15384 desired XML namespace of the result. If no particular namespace
15385 is wanted, an empty string should be passed.
15389 The following functions return XML Schema documents describing the
15390 mappings performed by the corresponding functions above:
15392 <function>table_to_xmlschema
</function> (
<parameter>table
</parameter> <type>regclass
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15393 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15394 <function>query_to_xmlschema
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15395 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15396 <function>cursor_to_xmlschema
</function> (
<parameter>cursor
</parameter> <type>refcursor
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15397 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15399 It is essential that the same parameters are passed in order to
15400 obtain matching XML data mappings and XML Schema documents.
15404 The following functions produce XML data mappings and the
15405 corresponding XML Schema in one document (or forest), linked
15406 together. They can be useful where self-contained and
15407 self-describing results are wanted:
15409 <function>table_to_xml_and_xmlschema
</function> (
<parameter>table
</parameter> <type>regclass
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15410 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15411 <function>query_to_xml_and_xmlschema
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15412 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15417 In addition, the following functions are available to produce
15418 analogous mappings of entire schemas or the entire current
15421 <function>schema_to_xml
</function> (
<parameter>schema
</parameter> <type>name
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15422 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15423 <function>schema_to_xmlschema
</function> (
<parameter>schema
</parameter> <type>name
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15424 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15425 <function>schema_to_xml_and_xmlschema
</function> (
<parameter>schema
</parameter> <type>name
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15426 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15428 <function>database_to_xml
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15429 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15430 <function>database_to_xmlschema
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15431 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15432 <function>database_to_xml_and_xmlschema
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15433 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15436 These functions ignore tables that are not readable by the current user.
15437 The database-wide functions additionally ignore schemas that the current
15438 user does not have
<literal>USAGE
</literal> (lookup) privilege for.
15442 Note that these potentially produce a lot of data, which needs to
15443 be built up in memory. When requesting content mappings of large
15444 schemas or databases, it might be worthwhile to consider mapping the
15445 tables separately instead, possibly even through a cursor.
15449 The result of a schema content mapping looks like this:
15460 </schemaname>]]
></screen>
15462 where the format of a table mapping depends on the
15463 <parameter>tableforest
</parameter> parameter as explained above.
15467 The result of a database content mapping looks like this:
15482 </dbname>]]
></screen>
15484 where the schema mapping is as above.
15488 As an example of using the output produced by these functions,
15489 <xref linkend=
"xslt-xml-html"/> shows an XSLT stylesheet that
15490 converts the output of
15491 <function>table_to_xml_and_xmlschema
</function> to an HTML
15492 document containing a tabular rendition of the table data. In a
15493 similar manner, the results from these functions can be
15494 converted into other XML-based formats.
15497 <example id=
"xslt-xml-html">
15498 <title>XSLT Stylesheet for Converting SQL/XML Output to HTML
</title>
15499 <programlisting><![CDATA[
15500 <?xml version=
"1.0"?>
15501 <xsl:stylesheet version=
"1.0"
15502 xmlns:
xsl=
"http://www.w3.org/1999/XSL/Transform"
15503 xmlns:
xsd=
"http://www.w3.org/2001/XMLSchema"
15504 xmlns=
"http://www.w3.org/1999/xhtml"
15507 <xsl:output method=
"xml"
15508 doctype-system=
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
15509 doctype-public=
"-//W3C/DTD XHTML 1.0 Strict//EN"
15512 <xsl:template match=
"/*">
15513 <xsl:variable name=
"schema" select=
"//xsd:schema"/>
15514 <xsl:variable name=
"tabletypename"
15515 select=
"$schema/xsd:element[@name=name(current())]/@type"/>
15516 <xsl:variable name=
"rowtypename"
15517 select=
"$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
15521 <title><xsl:value-of select=
"name(current())"/></title>
15526 <xsl:for-each select=
"$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
15527 <th><xsl:value-of select=
"."/></th>
15531 <xsl:for-each select=
"row">
15533 <xsl:for-each select=
"*">
15534 <td><xsl:value-of select=
"."/></td>
15544 ]]
></programlisting>
15549 <sect1 id=
"functions-json">
15550 <title>JSON Functions and Operators
</title>
15552 <indexterm zone=
"functions-json">
15553 <primary>JSON
</primary>
15554 <secondary>functions and operators
</secondary>
15556 <indexterm zone=
"functions-json">
15557 <primary>SQL/JSON
</primary>
15558 <secondary>functions and expressions
</secondary>
15562 This section describes:
15567 functions and operators for processing and creating JSON data
15572 the SQL/JSON path language
15577 the SQL/JSON query functions
15584 To provide native support for JSON data types within the SQL environment,
15585 <productname>PostgreSQL
</productname> implements the
15586 <firstterm>SQL/JSON data model
</firstterm>.
15587 This model comprises sequences of items. Each item can hold SQL scalar
15588 values, with an additional SQL/JSON null value, and composite data structures
15589 that use JSON arrays and objects. The model is a formalization of the implied
15590 data model in the JSON specification
15591 <ulink url=
"https://datatracker.ietf.org/doc/html/rfc7159">RFC
7159</ulink>.
15595 SQL/JSON allows you to handle JSON data alongside regular SQL data,
15596 with transaction support, including:
15601 Uploading JSON data into the database and storing it in
15602 regular SQL columns as character or binary strings.
15607 Generating JSON objects and arrays from relational data.
15612 Querying JSON data using SQL/JSON query functions and
15613 SQL/JSON path language expressions.
15620 To learn more about the SQL/JSON standard, see
15621 <xref linkend=
"sqltr-19075-6"/>. For details on JSON types
15622 supported in
<productname>PostgreSQL
</productname>,
15623 see
<xref linkend=
"datatype-json"/>.
15626 <sect2 id=
"functions-json-processing">
15627 <title>Processing and Creating JSON Data
</title>
15630 <xref linkend=
"functions-json-op-table"/> shows the operators that
15631 are available for use with JSON data types (see
<xref
15632 linkend=
"datatype-json"/>).
15633 In addition, the usual comparison operators shown in
<xref
15634 linkend=
"functions-comparison-op-table"/> are available for
15635 <type>jsonb
</type>, though not for
<type>json
</type>. The comparison
15636 operators follow the ordering rules for B-tree operations outlined in
15637 <xref linkend=
"json-indexing"/>.
15638 See also
<xref linkend=
"functions-aggregate"/> for the aggregate
15639 function
<function>json_agg
</function> which aggregates record
15640 values as JSON, the aggregate function
15641 <function>json_object_agg
</function> which aggregates pairs of values
15642 into a JSON object, and their
<type>jsonb
</type> equivalents,
15643 <function>jsonb_agg
</function> and
<function>jsonb_object_agg
</function>.
15646 <table id=
"functions-json-op-table">
15647 <title><type>json
</type> and
<type>jsonb
</type> Operators
</title>
15651 <entry role=
"func_table_entry"><para role=
"func_signature">
15665 <entry role=
"func_table_entry"><para role=
"func_signature">
15666 <type>json
</type> <literal>-
></literal> <type>integer
</type>
15667 <returnvalue>json
</returnvalue>
15669 <para role=
"func_signature">
15670 <type>jsonb
</type> <literal>-
></literal> <type>integer
</type>
15671 <returnvalue>jsonb
</returnvalue>
15674 Extracts
<parameter>n
</parameter>'th element of JSON array
15675 (array elements are indexed from zero, but negative integers count
15679 <literal>'[{
"a":
"foo"},{
"b":
"bar"},{
"c":
"baz"}]'::json -
> 2</literal>
15680 <returnvalue>{
"c":
"baz"}
</returnvalue>
15683 <literal>'[{
"a":
"foo"},{
"b":
"bar"},{
"c":
"baz"}]'::json -
> -
3</literal>
15684 <returnvalue>{
"a":
"foo"}
</returnvalue>
15689 <entry role=
"func_table_entry"><para role=
"func_signature">
15690 <type>json
</type> <literal>-
></literal> <type>text
</type>
15691 <returnvalue>json
</returnvalue>
15693 <para role=
"func_signature">
15694 <type>jsonb
</type> <literal>-
></literal> <type>text
</type>
15695 <returnvalue>jsonb
</returnvalue>
15698 Extracts JSON object field with the given key.
15701 <literal>'{
"a": {
"b":
"foo"}}'::json -
> 'a'
</literal>
15702 <returnvalue>{
"b":
"foo"}
</returnvalue>
15707 <entry role=
"func_table_entry"><para role=
"func_signature">
15708 <type>json
</type> <literal>-
>></literal> <type>integer
</type>
15709 <returnvalue>text
</returnvalue>
15711 <para role=
"func_signature">
15712 <type>jsonb
</type> <literal>-
>></literal> <type>integer
</type>
15713 <returnvalue>text
</returnvalue>
15716 Extracts
<parameter>n
</parameter>'th element of JSON array,
15717 as
<type>text
</type>.
15720 <literal>'[
1,
2,
3]'::json -
>> 2</literal>
15721 <returnvalue>3</returnvalue>
15726 <entry role=
"func_table_entry"><para role=
"func_signature">
15727 <type>json
</type> <literal>-
>></literal> <type>text
</type>
15728 <returnvalue>text
</returnvalue>
15730 <para role=
"func_signature">
15731 <type>jsonb
</type> <literal>-
>></literal> <type>text
</type>
15732 <returnvalue>text
</returnvalue>
15735 Extracts JSON object field with the given key, as
<type>text
</type>.
15738 <literal>'{
"a":
1,
"b":
2}'::json -
>> 'b'
</literal>
15739 <returnvalue>2</returnvalue>
15744 <entry role=
"func_table_entry"><para role=
"func_signature">
15745 <type>json
</type> <literal>#
></literal> <type>text[]
</type>
15746 <returnvalue>json
</returnvalue>
15748 <para role=
"func_signature">
15749 <type>jsonb
</type> <literal>#
></literal> <type>text[]
</type>
15750 <returnvalue>jsonb
</returnvalue>
15753 Extracts JSON sub-object at the specified path, where path elements
15754 can be either field keys or array indexes.
15757 <literal>'{
"a": {
"b": [
"foo",
"bar"]}}'::json #
> '{a,b,
1}'
</literal>
15758 <returnvalue>"bar"</returnvalue>
15763 <entry role=
"func_table_entry"><para role=
"func_signature">
15764 <type>json
</type> <literal>#
>></literal> <type>text[]
</type>
15765 <returnvalue>text
</returnvalue>
15767 <para role=
"func_signature">
15768 <type>jsonb
</type> <literal>#
>></literal> <type>text[]
</type>
15769 <returnvalue>text
</returnvalue>
15772 Extracts JSON sub-object at the specified path as
<type>text
</type>.
15775 <literal>'{
"a": {
"b": [
"foo",
"bar"]}}'::json #
>> '{a,b,
1}'
</literal>
15776 <returnvalue>bar
</returnvalue>
15785 The field/element/path extraction operators return NULL, rather than
15786 failing, if the JSON input does not have the right structure to match
15787 the request; for example if no such key or array element exists.
15792 Some further operators exist only for
<type>jsonb
</type>, as shown
15793 in
<xref linkend=
"functions-jsonb-op-table"/>.
15794 <xref linkend=
"json-indexing"/>
15795 describes how these operators can be used to effectively search indexed
15796 <type>jsonb
</type> data.
15799 <table id=
"functions-jsonb-op-table">
15800 <title>Additional
<type>jsonb
</type> Operators
</title>
15804 <entry role=
"func_table_entry"><para role=
"func_signature">
15818 <entry role=
"func_table_entry"><para role=
"func_signature">
15819 <type>jsonb
</type> <literal>@
></literal> <type>jsonb
</type>
15820 <returnvalue>boolean
</returnvalue>
15823 Does the first JSON value contain the second?
15824 (See
<xref linkend=
"json-containment"/> for details about containment.)
15827 <literal>'{
"a":
1,
"b":
2}'::jsonb
@> '{
"b":
2}'::jsonb
</literal>
15828 <returnvalue>t
</returnvalue>
15833 <entry role=
"func_table_entry"><para role=
"func_signature">
15834 <type>jsonb
</type> <literal><@
</literal> <type>jsonb
</type>
15835 <returnvalue>boolean
</returnvalue>
15838 Is the first JSON value contained in the second?
15841 <literal>'{
"b":
2}'::jsonb
<@ '{
"a":
1,
"b":
2}'::jsonb
</literal>
15842 <returnvalue>t
</returnvalue>
15847 <entry role=
"func_table_entry"><para role=
"func_signature">
15848 <type>jsonb
</type> <literal>?
</literal> <type>text
</type>
15849 <returnvalue>boolean
</returnvalue>
15852 Does the text string exist as a top-level key or array element within
15856 <literal>'{
"a":
1,
"b":
2}'::jsonb ? 'b'
</literal>
15857 <returnvalue>t
</returnvalue>
15860 <literal>'[
"a",
"b",
"c"]'::jsonb ? 'b'
</literal>
15861 <returnvalue>t
</returnvalue>
15866 <entry role=
"func_table_entry"><para role=
"func_signature">
15867 <type>jsonb
</type> <literal>?|
</literal> <type>text[]
</type>
15868 <returnvalue>boolean
</returnvalue>
15871 Do any of the strings in the text array exist as top-level keys or
15875 <literal>'{
"a":
1,
"b":
2,
"c":
3}'::jsonb ?| array['b', 'd']
</literal>
15876 <returnvalue>t
</returnvalue>
15881 <entry role=
"func_table_entry"><para role=
"func_signature">
15882 <type>jsonb
</type> <literal>?
&</literal> <type>text[]
</type>
15883 <returnvalue>boolean
</returnvalue>
15886 Do all of the strings in the text array exist as top-level keys or
15890 <literal>'[
"a",
"b",
"c"]'::jsonb ?
& array['a', 'b']
</literal>
15891 <returnvalue>t
</returnvalue>
15896 <entry role=
"func_table_entry"><para role=
"func_signature">
15897 <type>jsonb
</type> <literal>||
</literal> <type>jsonb
</type>
15898 <returnvalue>jsonb
</returnvalue>
15901 Concatenates two
<type>jsonb
</type> values.
15902 Concatenating two arrays generates an array containing all the
15903 elements of each input. Concatenating two objects generates an
15904 object containing the union of their
15905 keys, taking the second object's value when there are duplicate keys.
15906 All other cases are treated by converting a non-array input into a
15907 single-element array, and then proceeding as for two arrays.
15908 Does not operate recursively: only the top-level array or object
15909 structure is merged.
15912 <literal>'[
"a",
"b"]'::jsonb || '[
"a",
"d"]'::jsonb
</literal>
15913 <returnvalue>[
"a",
"b",
"a",
"d"]
</returnvalue>
15916 <literal>'{
"a":
"b"}'::jsonb || '{
"c":
"d"}'::jsonb
</literal>
15917 <returnvalue>{
"a":
"b",
"c":
"d"}
</returnvalue>
15920 <literal>'[
1,
2]'::jsonb || '
3'::jsonb
</literal>
15921 <returnvalue>[
1,
2,
3]
</returnvalue>
15924 <literal>'{
"a":
"b"}'::jsonb || '
42'::jsonb
</literal>
15925 <returnvalue>[{
"a":
"b"},
42]
</returnvalue>
15928 To append an array to another array as a single entry, wrap it
15929 in an additional layer of array, for example:
15932 <literal>'[
1,
2]'::jsonb || jsonb_build_array('[
3,
4]'::jsonb)
</literal>
15933 <returnvalue>[
1,
2, [
3,
4]]
</returnvalue>
15938 <entry role=
"func_table_entry"><para role=
"func_signature">
15939 <type>jsonb
</type> <literal>-
</literal> <type>text
</type>
15940 <returnvalue>jsonb
</returnvalue>
15943 Deletes a key (and its value) from a JSON object, or matching string
15944 value(s) from a JSON array.
15947 <literal>'{
"a":
"b",
"c":
"d"}'::jsonb - 'a'
</literal>
15948 <returnvalue>{
"c":
"d"}
</returnvalue>
15951 <literal>'[
"a",
"b",
"c",
"b"]'::jsonb - 'b'
</literal>
15952 <returnvalue>[
"a",
"c"]
</returnvalue>
15957 <entry role=
"func_table_entry"><para role=
"func_signature">
15958 <type>jsonb
</type> <literal>-
</literal> <type>text[]
</type>
15959 <returnvalue>jsonb
</returnvalue>
15962 Deletes all matching keys or array elements from the left operand.
15965 <literal>'{
"a":
"b",
"c":
"d"}'::jsonb - '{a,c}'::text[]
</literal>
15966 <returnvalue>{}
</returnvalue>
15971 <entry role=
"func_table_entry"><para role=
"func_signature">
15972 <type>jsonb
</type> <literal>-
</literal> <type>integer
</type>
15973 <returnvalue>jsonb
</returnvalue>
15976 Deletes the array element with specified index (negative
15977 integers count from the end). Throws an error if JSON value
15981 <literal>'[
"a",
"b"]'::jsonb -
1 </literal>
15982 <returnvalue>[
"a"]
</returnvalue>
15987 <entry role=
"func_table_entry"><para role=
"func_signature">
15988 <type>jsonb
</type> <literal>#-
</literal> <type>text[]
</type>
15989 <returnvalue>jsonb
</returnvalue>
15992 Deletes the field or array element at the specified path, where path
15993 elements can be either field keys or array indexes.
15996 <literal>'[
"a", {
"b":
1}]'::jsonb #- '{
1,b}'
</literal>
15997 <returnvalue>[
"a", {}]
</returnvalue>
16002 <entry role=
"func_table_entry"><para role=
"func_signature">
16003 <type>jsonb
</type> <literal>@?
</literal> <type>jsonpath
</type>
16004 <returnvalue>boolean
</returnvalue>
16007 Does JSON path return any item for the specified JSON value?
16008 (This is useful only with SQL-standard JSON path expressions, not
16009 <link linkend=
"functions-sqljson-check-expressions">predicate check
16010 expressions
</link>, since those always return a value.)
16013 <literal>'{
"a":[
1,
2,
3,
4,
5]}'::jsonb @? '$.a[*] ? (@
> 2)'
</literal>
16014 <returnvalue>t
</returnvalue>
16019 <entry role=
"func_table_entry"><para role=
"func_signature">
16020 <type>jsonb
</type> <literal>@@
</literal> <type>jsonpath
</type>
16021 <returnvalue>boolean
</returnvalue>
16024 Returns the result of a JSON path predicate check for the
16025 specified JSON value.
16026 (This is useful only
16027 with
<link linkend=
"functions-sqljson-check-expressions">predicate
16028 check expressions
</link>, not SQL-standard JSON path expressions,
16029 since it will return
<literal>NULL
</literal> if the path result is
16030 not a single boolean value.)
16033 <literal>'{
"a":[
1,
2,
3,
4,
5]}'::jsonb @@ '$.a[*]
> 2'
</literal>
16034 <returnvalue>t
</returnvalue>
16043 The
<type>jsonpath
</type> operators
<literal>@?
</literal>
16044 and
<literal>@@
</literal> suppress the following errors: missing object
16045 field or array element, unexpected JSON item type, datetime and numeric
16046 errors. The
<type>jsonpath
</type>-related functions described below can
16047 also be told to suppress these types of errors. This behavior might be
16048 helpful when searching JSON document collections of varying structure.
16053 <xref linkend=
"functions-json-creation-table"/> shows the functions that are
16054 available for constructing
<type>json
</type> and
<type>jsonb
</type> values.
16055 Some functions in this table have a
<literal>RETURNING
</literal> clause,
16056 which specifies the data type returned. It must be one of
<type>json
</type>,
16057 <type>jsonb
</type>,
<type>bytea
</type>, a character string type (
<type>text
</type>,
16058 <type>char
</type>, or
<type>varchar
</type>), or a type
16059 that can be cast to
<type>json
</type>.
16060 By default, the
<type>json
</type> type is returned.
16063 <table id=
"functions-json-creation-table">
16064 <title>JSON Creation Functions
</title>
16068 <entry role=
"func_table_entry"><para role=
"func_signature">
16082 <entry role=
"func_table_entry"><para role=
"func_signature">
16084 <primary>to_json
</primary>
16086 <function>to_json
</function> (
<type>anyelement
</type> )
16087 <returnvalue>json
</returnvalue>
16089 <para role=
"func_signature">
16091 <primary>to_jsonb
</primary>
16093 <function>to_jsonb
</function> (
<type>anyelement
</type> )
16094 <returnvalue>jsonb
</returnvalue>
16097 Converts any SQL value to
<type>json
</type> or
<type>jsonb
</type>.
16098 Arrays and composites are converted recursively to arrays and
16099 objects (multidimensional arrays become arrays of arrays in JSON).
16100 Otherwise, if there is a cast from the SQL data type
16101 to
<type>json
</type>, the cast function will be used to perform the
16102 conversion;
<footnote>
16104 For example, the
<xref linkend=
"hstore"/> extension has a cast
16105 from
<type>hstore
</type> to
<type>json
</type>, so that
16106 <type>hstore
</type> values converted via the JSON creation functions
16107 will be represented as JSON objects, not as primitive string values.
16110 otherwise, a scalar JSON value is produced. For any scalar other than
16111 a number, a Boolean, or a null value, the text representation will be
16112 used, with escaping as necessary to make it a valid JSON string value.
16115 <literal>to_json('Fred said
"Hi."'::text)
</literal>
16116 <returnvalue>"Fred said \"Hi.\
""</returnvalue>
16119 <literal>to_jsonb(row(
42, 'Fred said
"Hi."'::text))
</literal>
16120 <returnvalue>{
"f1":
42,
"f2":
"Fred said \"Hi.\
""}
</returnvalue>
16125 <entry role=
"func_table_entry"><para role=
"func_signature">
16127 <primary>array_to_json
</primary>
16129 <function>array_to_json
</function> (
<type>anyarray
</type> <optional>,
<type>boolean
</type> </optional> )
16130 <returnvalue>json
</returnvalue>
16133 Converts an SQL array to a JSON array. The behavior is the same
16134 as
<function>to_json
</function> except that line feeds will be added
16135 between top-level array elements if the optional boolean parameter is
16139 <literal>array_to_json('{{
1,
5},{
99,
100}}'::int[])
</literal>
16140 <returnvalue>[[
1,
5],[
99,
100]]
</returnvalue>
16146 Note that this is barely legible in the output; it looks like a
16147 salad of braces and brackets. It would be better to split it out
16148 in multiple lines, but that's surprisingly hard to do in a way that
16149 matches in HTML and PDF output. Other standard SQL/JSON functions
16150 have the same problem.
16152 <entry role=
"func_table_entry"><para role=
"func_signature">
16153 <indexterm><primary>json_array
</primary></indexterm>
16154 <function>json_array
</function> (
16155 <optional> {
<replaceable>value_expression
</replaceable> <optional> <literal>FORMAT JSON
</literal> </optional> }
<optional>, ...
</optional> </optional>
16156 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
16157 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
16159 <para role=
"func_signature">
16160 <function>json_array
</function> (
16161 <optional> <replaceable>query_expression
</replaceable> </optional>
16162 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
16165 Constructs a JSON array from either a series of
16166 <replaceable>value_expression
</replaceable> parameters or from the results
16167 of
<replaceable>query_expression
</replaceable>,
16168 which must be a SELECT query returning a single column. If
16169 <literal>ABSENT ON NULL
</literal> is specified, NULL values are ignored.
16170 This is always the case if a
16171 <replaceable>query_expression
</replaceable> is used.
16174 <literal>json_array(
1,true,json '{
"a":null}')
</literal>
16175 <returnvalue>[
1, true, {
"a":null}]
</returnvalue>
16178 <literal>json_array(SELECT * FROM (VALUES(
1),(
2)) t)
</literal>
16179 <returnvalue>[
1,
2]
</returnvalue>
16184 <entry role=
"func_table_entry"><para role=
"func_signature">
16186 <primary>row_to_json
</primary>
16188 <function>row_to_json
</function> (
<type>record
</type> <optional>,
<type>boolean
</type> </optional> )
16189 <returnvalue>json
</returnvalue>
16192 Converts an SQL composite value to a JSON object. The behavior is the
16193 same as
<function>to_json
</function> except that line feeds will be
16194 added between top-level elements if the optional boolean parameter is
16198 <literal>row_to_json(row(
1,'foo'))
</literal>
16199 <returnvalue>{
"f1":
1,
"f2":
"foo"}
</returnvalue>
16204 <entry role=
"func_table_entry"><para role=
"func_signature">
16206 <primary>json_build_array
</primary>
16208 <function>json_build_array
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16209 <returnvalue>json
</returnvalue>
16211 <para role=
"func_signature">
16213 <primary>jsonb_build_array
</primary>
16215 <function>jsonb_build_array
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16216 <returnvalue>jsonb
</returnvalue>
16219 Builds a possibly-heterogeneously-typed JSON array out of a variadic
16220 argument list. Each argument is converted as
16221 per
<function>to_json
</function> or
<function>to_jsonb
</function>.
16224 <literal>json_build_array(
1,
2, 'foo',
4,
5)
</literal>
16225 <returnvalue>[
1,
2,
"foo",
4,
5]
</returnvalue>
16230 <entry role=
"func_table_entry"><para role=
"func_signature">
16232 <primary>json_build_object
</primary>
16234 <function>json_build_object
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16235 <returnvalue>json
</returnvalue>
16237 <para role=
"func_signature">
16239 <primary>jsonb_build_object
</primary>
16241 <function>jsonb_build_object
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16242 <returnvalue>jsonb
</returnvalue>
16245 Builds a JSON object out of a variadic argument list. By convention,
16246 the argument list consists of alternating keys and values. Key
16247 arguments are coerced to text; value arguments are converted as
16248 per
<function>to_json
</function> or
<function>to_jsonb
</function>.
16251 <literal>json_build_object('foo',
1,
2, row(
3,'bar'))
</literal>
16252 <returnvalue>{
"foo" :
1,
"2" : {
"f1":
3,
"f2":
"bar"}}
</returnvalue>
16257 <entry role=
"func_table_entry"><para role=
"func_signature">
16258 <indexterm><primary>json_object
</primary></indexterm>
16259 <function>json_object
</function> (
16260 <optional> {
<replaceable>key_expression
</replaceable> {
<literal>VALUE
</literal> | ':' }
16261 <replaceable>value_expression
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> }
<optional>, ...
</optional> </optional>
16262 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
16263 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional> </optional>
16264 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
16267 Constructs a JSON object of all the key/value pairs given,
16268 or an empty object if none are given.
16269 <replaceable>key_expression
</replaceable> is a scalar expression
16270 defining the
<acronym>JSON
</acronym> key, which is
16271 converted to the
<type>text
</type> type.
16272 It cannot be
<literal>NULL
</literal> nor can it
16273 belong to a type that has a cast to the
<type>json
</type> type.
16274 If
<literal>WITH UNIQUE KEYS
</literal> is specified, there must not
16275 be any duplicate
<replaceable>key_expression
</replaceable>.
16276 Any pair for which the
<replaceable>value_expression
</replaceable>
16277 evaluates to
<literal>NULL
</literal> is omitted from the output
16278 if
<literal>ABSENT ON NULL
</literal> is specified;
16279 if
<literal>NULL ON NULL
</literal> is specified or the clause
16280 omitted, the key is included with value
<literal>NULL
</literal>.
16283 <literal>json_object('code' VALUE 'P123', 'title': 'Jaws')
</literal>
16284 <returnvalue>{
"code" :
"P123",
"title" :
"Jaws"}
</returnvalue>
16289 <entry role=
"func_table_entry"><para role=
"func_signature">
16291 <primary>json_object
</primary>
16293 <function>json_object
</function> (
<type>text[]
</type> )
16294 <returnvalue>json
</returnvalue>
16296 <para role=
"func_signature">
16298 <primary>jsonb_object
</primary>
16300 <function>jsonb_object
</function> (
<type>text[]
</type> )
16301 <returnvalue>jsonb
</returnvalue>
16304 Builds a JSON object out of a text array. The array must have either
16305 exactly one dimension with an even number of members, in which case
16306 they are taken as alternating key/value pairs, or two dimensions
16307 such that each inner array has exactly two elements, which
16308 are taken as a key/value pair. All values are converted to JSON
16312 <literal>json_object('{a,
1, b,
"def", c,
3.5}')
</literal>
16313 <returnvalue>{
"a" :
"1",
"b" :
"def",
"c" :
"3.5"}
</returnvalue>
16315 <para><literal>json_object('{{a,
1}, {b,
"def"}, {c,
3.5}}')
</literal>
16316 <returnvalue>{
"a" :
"1",
"b" :
"def",
"c" :
"3.5"}
</returnvalue>
16321 <entry role=
"func_table_entry"><para role=
"func_signature">
16322 <function>json_object
</function> (
<parameter>keys
</parameter> <type>text[]
</type>,
<parameter>values
</parameter> <type>text[]
</type> )
16323 <returnvalue>json
</returnvalue>
16325 <para role=
"func_signature">
16326 <function>jsonb_object
</function> (
<parameter>keys
</parameter> <type>text[]
</type>,
<parameter>values
</parameter> <type>text[]
</type> )
16327 <returnvalue>jsonb
</returnvalue>
16330 This form of
<function>json_object
</function> takes keys and values
16331 pairwise from separate text arrays. Otherwise it is identical to
16332 the one-argument form.
16335 <literal>json_object('{a,b}', '{
1,
2}')
</literal>
16336 <returnvalue>{
"a":
"1",
"b":
"2"}
</returnvalue>
16340 <entry role=
"func_table_entry">
16341 <para role=
"func_signature">
16342 <indexterm><primary>json constructor
</primary></indexterm>
16343 <function>json
</function> (
16344 <replaceable>expression
</replaceable>
16345 <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional></optional>
16346 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional></optional> )
16347 <returnvalue>json
</returnvalue>
16350 Converts a given expression specified as
<type>text
</type> or
16351 <type>bytea
</type> string (in UTF8 encoding) into a JSON
16352 value. If
<replaceable>expression
</replaceable> is NULL, an
16353 <acronym>SQL
</acronym> null value is returned.
16354 If
<literal>WITH UNIQUE
</literal> is specified, the
16355 <replaceable>expression
</replaceable> must not contain any duplicate
16359 <literal>json('{
"a":
123,
"b":[true,
"foo"],
"a":
"bar"}')
</literal>
16360 <returnvalue>{
"a":
123,
"b":[true,
"foo"],
"a":
"bar"}
</returnvalue>
16365 <entry role=
"func_table_entry">
16366 <para role=
"func_signature">
16367 <indexterm><primary>json_scalar
</primary></indexterm>
16368 <function>json_scalar
</function> (
<replaceable>expression
</replaceable> )
16371 Converts a given SQL scalar value into a JSON scalar value.
16372 If the input is NULL, an
<acronym>SQL
</acronym> null is returned. If
16373 the input is number or a boolean value, a corresponding JSON number
16374 or boolean value is returned. For any other value, a JSON string is
16378 <literal>json_scalar(
123.45)
</literal>
16379 <returnvalue>123.45</returnvalue>
16382 <literal>json_scalar(CURRENT_TIMESTAMP)
</literal>
16383 <returnvalue>"2022-05-10T10:51:04.62128-04:00"</returnvalue>
16387 <entry role=
"func_table_entry">
16388 <para role=
"func_signature">
16389 <function>json_serialize
</function> (
16390 <replaceable>expression
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional>
16391 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional> )
16394 Converts an SQL/JSON expression into a character or binary string. The
16395 <replaceable>expression
</replaceable> can be of any JSON type, any
16396 character string type, or
<type>bytea
</type> in UTF8 encoding.
16397 The returned type used in
<literal> RETURNING
</literal> can be any
16398 character string type or
<type>bytea
</type>. The default is
16402 <literal>json_serialize('{
"a" :
1 } ' RETURNING bytea)
</literal>
16403 <returnvalue>\x7b20226122203a2031207d20
</returnvalue>
16411 <xref linkend=
"functions-sqljson-misc" /> details SQL/JSON
16412 facilities for testing JSON.
16415 <table id=
"functions-sqljson-misc">
16416 <title>SQL/JSON Testing Functions
</title>
16420 <entry role=
"func_table_entry"><para role=
"func_signature">
16433 <entry role=
"func_table_entry"><para role=
"func_signature">
16434 <indexterm><primary>IS JSON
</primary></indexterm>
16435 <replaceable>expression
</replaceable> <literal>IS
</literal> <optional> <literal>NOT
</literal> </optional> <literal>JSON
</literal>
16436 <optional> {
<literal>VALUE
</literal> |
<literal>SCALAR
</literal> |
<literal>ARRAY
</literal> |
<literal>OBJECT
</literal> }
</optional>
16437 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional> </optional>
16440 This predicate tests whether
<replaceable>expression
</replaceable> can be
16441 parsed as JSON, possibly of a specified type.
16442 If
<literal>SCALAR
</literal> or
<literal>ARRAY
</literal> or
16443 <literal>OBJECT
</literal> is specified, the
16444 test is whether or not the JSON is of that particular type. If
16445 <literal>WITH UNIQUE KEYS
</literal> is specified, then any object in the
16446 <replaceable>expression
</replaceable> is also tested to see if it
16447 has duplicate keys.
16452 js IS JSON
"json?",
16453 js IS JSON SCALAR
"scalar?",
16454 js IS JSON OBJECT
"object?",
16455 js IS JSON ARRAY
"array?"
16457 ('
123'), ('
"abc"'), ('{
"a":
"b"}'), ('[
1,
2]'),('abc')) foo(js);
16458 js | json? | scalar? | object? | array?
16459 ------------+-------+---------+---------+--------
16460 123 | t | t | f | f
16461 "abc" | t | t | f | f
16462 {
"a":
"b"} | t | f | t | f
16463 [
1,
2] | t | f | f | t
16464 abc | f | f | f | f
16470 js IS JSON OBJECT
"object?",
16471 js IS JSON ARRAY
"array?",
16472 js IS JSON ARRAY WITH UNIQUE KEYS
"array w. UK?",
16473 js IS JSON ARRAY WITHOUT UNIQUE KEYS
"array w/o UK?"
16474 FROM (VALUES ('[{
"a":
"1"},
16475 {
"b":
"2",
"b":
"3"}]')) foo(js);
16476 -[ RECORD
1 ]-+--------------------
16478 | {
"b":
"2",
"b":
"3"}]
16491 <xref linkend=
"functions-json-processing-table"/> shows the functions that
16492 are available for processing
<type>json
</type> and
<type>jsonb
</type> values.
16495 <table id=
"functions-json-processing-table">
16496 <title>JSON Processing Functions
</title>
16500 <entry role=
"func_table_entry"><para role=
"func_signature">
16514 <entry role=
"func_table_entry"><para role=
"func_signature">
16516 <primary>json_array_elements
</primary>
16518 <function>json_array_elements
</function> (
<type>json
</type> )
16519 <returnvalue>setof json
</returnvalue>
16521 <para role=
"func_signature">
16523 <primary>jsonb_array_elements
</primary>
16525 <function>jsonb_array_elements
</function> (
<type>jsonb
</type> )
16526 <returnvalue>setof jsonb
</returnvalue>
16529 Expands the top-level JSON array into a set of JSON values.
16532 <literal>select * from json_array_elements('[
1,true, [
2,false]]')
</literal>
16533 <returnvalue></returnvalue>
16545 <entry role=
"func_table_entry"><para role=
"func_signature">
16547 <primary>json_array_elements_text
</primary>
16549 <function>json_array_elements_text
</function> (
<type>json
</type> )
16550 <returnvalue>setof text
</returnvalue>
16552 <para role=
"func_signature">
16554 <primary>jsonb_array_elements_text
</primary>
16556 <function>jsonb_array_elements_text
</function> (
<type>jsonb
</type> )
16557 <returnvalue>setof text
</returnvalue>
16560 Expands the top-level JSON array into a set of
<type>text
</type> values.
16563 <literal>select * from json_array_elements_text('[
"foo",
"bar"]')
</literal>
16564 <returnvalue></returnvalue>
16575 <entry role=
"func_table_entry"><para role=
"func_signature">
16577 <primary>json_array_length
</primary>
16579 <function>json_array_length
</function> (
<type>json
</type> )
16580 <returnvalue>integer
</returnvalue>
16582 <para role=
"func_signature">
16584 <primary>jsonb_array_length
</primary>
16586 <function>jsonb_array_length
</function> (
<type>jsonb
</type> )
16587 <returnvalue>integer
</returnvalue>
16590 Returns the number of elements in the top-level JSON array.
16593 <literal>json_array_length('[
1,
2,
3,{
"f1":
1,
"f2":[
5,
6]},
4]')
</literal>
16594 <returnvalue>5</returnvalue>
16597 <literal>jsonb_array_length('[]')
</literal>
16598 <returnvalue>0</returnvalue>
16603 <entry role=
"func_table_entry"><para role=
"func_signature">
16605 <primary>json_each
</primary>
16607 <function>json_each
</function> (
<type>json
</type> )
16608 <returnvalue>setof record
</returnvalue>
16609 (
<parameter>key
</parameter> <type>text
</type>,
16610 <parameter>value
</parameter> <type>json
</type> )
16612 <para role=
"func_signature">
16614 <primary>jsonb_each
</primary>
16616 <function>jsonb_each
</function> (
<type>jsonb
</type> )
16617 <returnvalue>setof record
</returnvalue>
16618 (
<parameter>key
</parameter> <type>text
</type>,
16619 <parameter>value
</parameter> <type>jsonb
</type> )
16622 Expands the top-level JSON object into a set of key/value pairs.
16625 <literal>select * from json_each('{
"a":
"foo",
"b":
"bar"}')
</literal>
16626 <returnvalue></returnvalue>
16637 <entry role=
"func_table_entry"><para role=
"func_signature">
16639 <primary>json_each_text
</primary>
16641 <function>json_each_text
</function> (
<type>json
</type> )
16642 <returnvalue>setof record
</returnvalue>
16643 (
<parameter>key
</parameter> <type>text
</type>,
16644 <parameter>value
</parameter> <type>text
</type> )
16646 <para role=
"func_signature">
16648 <primary>jsonb_each_text
</primary>
16650 <function>jsonb_each_text
</function> (
<type>jsonb
</type> )
16651 <returnvalue>setof record
</returnvalue>
16652 (
<parameter>key
</parameter> <type>text
</type>,
16653 <parameter>value
</parameter> <type>text
</type> )
16656 Expands the top-level JSON object into a set of key/value pairs.
16657 The returned
<parameter>value
</parameter>s will be of
16658 type
<type>text
</type>.
16661 <literal>select * from json_each_text('{
"a":
"foo",
"b":
"bar"}')
</literal>
16662 <returnvalue></returnvalue>
16673 <entry role=
"func_table_entry"><para role=
"func_signature">
16675 <primary>json_extract_path
</primary>
16677 <function>json_extract_path
</function> (
<parameter>from_json
</parameter> <type>json
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16678 <returnvalue>json
</returnvalue>
16680 <para role=
"func_signature">
16682 <primary>jsonb_extract_path
</primary>
16684 <function>jsonb_extract_path
</function> (
<parameter>from_json
</parameter> <type>jsonb
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16685 <returnvalue>jsonb
</returnvalue>
16688 Extracts JSON sub-object at the specified path.
16689 (This is functionally equivalent to the
<literal>#
></literal>
16690 operator, but writing the path out as a variadic list can be more
16691 convenient in some cases.)
16694 <literal>json_extract_path('{
"f2":{
"f3":
1},
"f4":{
"f5":
99,
"f6":
"foo"}}', 'f4', 'f6')
</literal>
16695 <returnvalue>"foo"</returnvalue>
16700 <entry role=
"func_table_entry"><para role=
"func_signature">
16702 <primary>json_extract_path_text
</primary>
16704 <function>json_extract_path_text
</function> (
<parameter>from_json
</parameter> <type>json
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16705 <returnvalue>text
</returnvalue>
16707 <para role=
"func_signature">
16709 <primary>jsonb_extract_path_text
</primary>
16711 <function>jsonb_extract_path_text
</function> (
<parameter>from_json
</parameter> <type>jsonb
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16712 <returnvalue>text
</returnvalue>
16715 Extracts JSON sub-object at the specified path as
<type>text
</type>.
16716 (This is functionally equivalent to the
<literal>#
>></literal>
16720 <literal>json_extract_path_text('{
"f2":{
"f3":
1},
"f4":{
"f5":
99,
"f6":
"foo"}}', 'f4', 'f6')
</literal>
16721 <returnvalue>foo
</returnvalue>
16726 <entry role=
"func_table_entry"><para role=
"func_signature">
16728 <primary>json_object_keys
</primary>
16730 <function>json_object_keys
</function> (
<type>json
</type> )
16731 <returnvalue>setof text
</returnvalue>
16733 <para role=
"func_signature">
16735 <primary>jsonb_object_keys
</primary>
16737 <function>jsonb_object_keys
</function> (
<type>jsonb
</type> )
16738 <returnvalue>setof text
</returnvalue>
16741 Returns the set of keys in the top-level JSON object.
16744 <literal>select * from json_object_keys('{
"f1":
"abc",
"f2":{
"f3":
"a",
"f4":
"b"}}')
</literal>
16745 <returnvalue></returnvalue>
16756 <entry role=
"func_table_entry"><para role=
"func_signature">
16758 <primary>json_populate_record
</primary>
16760 <function>json_populate_record
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16761 <returnvalue>anyelement
</returnvalue>
16763 <para role=
"func_signature">
16765 <primary>jsonb_populate_record
</primary>
16767 <function>jsonb_populate_record
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>jsonb
</type> )
16768 <returnvalue>anyelement
</returnvalue>
16771 Expands the top-level JSON object to a row having the composite type
16772 of the
<parameter>base
</parameter> argument. The JSON object
16773 is scanned for fields whose names match column names of the output row
16774 type, and their values are inserted into those columns of the output.
16775 (Fields that do not correspond to any output column name are ignored.)
16776 In typical use, the value of
<parameter>base
</parameter> is just
16777 <literal>NULL
</literal>, which means that any output columns that do
16778 not match any object field will be filled with nulls. However,
16779 if
<parameter>base
</parameter> isn't
<literal>NULL
</literal> then
16780 the values it contains will be used for unmatched columns.
16783 To convert a JSON value to the SQL type of an output column, the
16784 following rules are applied in sequence:
16785 <itemizedlist spacing=
"compact">
16788 A JSON null value is converted to an SQL null in all cases.
16793 If the output column is of type
<type>json
</type>
16794 or
<type>jsonb
</type>, the JSON value is just reproduced exactly.
16799 If the output column is a composite (row) type, and the JSON value
16800 is a JSON object, the fields of the object are converted to columns
16801 of the output row type by recursive application of these rules.
16806 Likewise, if the output column is an array type and the JSON value
16807 is a JSON array, the elements of the JSON array are converted to
16808 elements of the output array by recursive application of these
16814 Otherwise, if the JSON value is a string, the contents of the
16815 string are fed to the input conversion function for the column's
16821 Otherwise, the ordinary text representation of the JSON value is
16822 fed to the input conversion function for the column's data type.
16828 While the example below uses a constant JSON value, typical use would
16829 be to reference a
<type>json
</type> or
<type>jsonb
</type> column
16830 laterally from another table in the query's
<literal>FROM
</literal>
16831 clause. Writing
<function>json_populate_record
</function> in
16832 the
<literal>FROM
</literal> clause is good practice, since all of the
16833 extracted columns are available for use without duplicate function
16837 <literal>create type subrowtype as (d int, e text);
</literal>
16838 <literal>create type myrowtype as (a int, b text[], c subrowtype);
</literal>
16841 <literal>select * from json_populate_record(null::myrowtype,
16842 '{
"a":
1,
"b": [
"2",
"a b"],
"c": {
"d":
4,
"e":
"a b c"},
"x":
"foo"}')
</literal>
16843 <returnvalue></returnvalue>
16846 ---+-----------+-------------
16847 1 | {
2,
"a b"} | (
4,
"a b c")
16853 <entry role=
"func_table_entry"><para role=
"func_signature">
16855 <primary>jsonb_populate_record_valid
</primary>
16857 <function>jsonb_populate_record_valid
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16858 <returnvalue>boolean
</returnvalue>
16861 Function for testing
<function>jsonb_populate_record
</function>. Returns
16862 <literal>true
</literal> if the input
<function>jsonb_populate_record
</function>
16863 would finish without an error for the given input JSON object; that is, it's
16864 valid input,
<literal>false
</literal> otherwise.
16867 <literal>create type jsb_char2 as (a char(
2));
</literal>
16870 <literal>select jsonb_populate_record_valid(NULL::jsb_char2, '{
"a":
"aaa"}');
</literal>
16871 <returnvalue></returnvalue>
16873 jsonb_populate_record_valid
16874 -----------------------------
16879 <literal>select * from jsonb_populate_record(NULL::jsb_char2, '{
"a":
"aaa"}') q;
</literal>
16880 <returnvalue></returnvalue>
16882 ERROR: value too long for type character(
2)
16884 <literal>select jsonb_populate_record_valid(NULL::jsb_char2, '{
"a":
"aa"}');
</literal>
16885 <returnvalue></returnvalue>
16887 jsonb_populate_record_valid
16888 -----------------------------
16893 <literal>select * from jsonb_populate_record(NULL::jsb_char2, '{
"a":
"aa"}') q;
</literal>
16894 <returnvalue></returnvalue>
16905 <entry role=
"func_table_entry"><para role=
"func_signature">
16907 <primary>json_populate_recordset
</primary>
16909 <function>json_populate_recordset
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16910 <returnvalue>setof anyelement
</returnvalue>
16912 <para role=
"func_signature">
16914 <primary>jsonb_populate_recordset
</primary>
16916 <function>jsonb_populate_recordset
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>jsonb
</type> )
16917 <returnvalue>setof anyelement
</returnvalue>
16920 Expands the top-level JSON array of objects to a set of rows having
16921 the composite type of the
<parameter>base
</parameter> argument.
16922 Each element of the JSON array is processed as described above
16923 for
<function>json[b]_populate_record
</function>.
16926 <literal>create type twoints as (a int, b int);
</literal>
16929 <literal>select * from json_populate_recordset(null::twoints, '[{
"a":
1,
"b":
2}, {
"a":
3,
"b":
4}]')
</literal>
16930 <returnvalue></returnvalue>
16941 <entry role=
"func_table_entry"><para role=
"func_signature">
16943 <primary>json_to_record
</primary>
16945 <function>json_to_record
</function> (
<type>json
</type> )
16946 <returnvalue>record
</returnvalue>
16948 <para role=
"func_signature">
16950 <primary>jsonb_to_record
</primary>
16952 <function>jsonb_to_record
</function> (
<type>jsonb
</type> )
16953 <returnvalue>record
</returnvalue>
16956 Expands the top-level JSON object to a row having the composite type
16957 defined by an
<literal>AS
</literal> clause. (As with all functions
16958 returning
<type>record
</type>, the calling query must explicitly
16959 define the structure of the record with an
<literal>AS
</literal>
16960 clause.) The output record is filled from fields of the JSON object,
16961 in the same way as described above
16962 for
<function>json[b]_populate_record
</function>. Since there is no
16963 input record value, unmatched columns are always filled with nulls.
16966 <literal>create type myrowtype as (a int, b text);
</literal>
16969 <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>
16970 <returnvalue></returnvalue>
16973 ---+---------+---------+---+---------------
16974 1 | [
1,
2,
3] | {
1,
2,
3} | | (
123,
"a b c")
16980 <entry role=
"func_table_entry"><para role=
"func_signature">
16982 <primary>json_to_recordset
</primary>
16984 <function>json_to_recordset
</function> (
<type>json
</type> )
16985 <returnvalue>setof record
</returnvalue>
16987 <para role=
"func_signature">
16989 <primary>jsonb_to_recordset
</primary>
16991 <function>jsonb_to_recordset
</function> (
<type>jsonb
</type> )
16992 <returnvalue>setof record
</returnvalue>
16995 Expands the top-level JSON array of objects to a set of rows having
16996 the composite type defined by an
<literal>AS
</literal> clause. (As
16997 with all functions returning
<type>record
</type>, the calling query
16998 must explicitly define the structure of the record with
16999 an
<literal>AS
</literal> clause.) Each element of the JSON array is
17000 processed as described above
17001 for
<function>json[b]_populate_record
</function>.
17004 <literal>select * from json_to_recordset('[{
"a":
1,
"b":
"foo"}, {
"a":
"2",
"c":
"bar"}]') as x(a int, b text)
</literal>
17005 <returnvalue></returnvalue>
17016 <entry role=
"func_table_entry"><para role=
"func_signature">
17018 <primary>jsonb_set
</primary>
17020 <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> )
17021 <returnvalue>jsonb
</returnvalue>
17024 Returns
<parameter>target
</parameter>
17025 with the item designated by
<parameter>path
</parameter>
17026 replaced by
<parameter>new_value
</parameter>, or with
17027 <parameter>new_value
</parameter> added if
17028 <parameter>create_if_missing
</parameter> is true (which is the
17029 default) and the item designated by
<parameter>path
</parameter>
17031 All earlier steps in the path must exist, or
17032 the
<parameter>target
</parameter> is returned unchanged.
17033 As with the path oriented operators, negative integers that
17034 appear in the
<parameter>path
</parameter> count from the end
17036 If the last path step is an array index that is out of range,
17037 and
<parameter>create_if_missing
</parameter> is true, the new
17038 value is added at the beginning of the array if the index is negative,
17039 or at the end of the array if it is positive.
17042 <literal>jsonb_set('[{
"f1":
1,
"f2":null},
2,null,
3]', '{
0,f1}', '[
2,
3,
4]', false)
</literal>
17043 <returnvalue>[{
"f1": [
2,
3,
4],
"f2": null},
2, null,
3]
</returnvalue>
17046 <literal>jsonb_set('[{
"f1":
1,
"f2":null},
2]', '{
0,f3}', '[
2,
3,
4]')
</literal>
17047 <returnvalue>[{
"f1":
1,
"f2": null,
"f3": [
2,
3,
4]},
2]
</returnvalue>
17052 <entry role=
"func_table_entry"><para role=
"func_signature">
17054 <primary>jsonb_set_lax
</primary>
17056 <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> )
17057 <returnvalue>jsonb
</returnvalue>
17060 If
<parameter>new_value
</parameter> is not
<literal>NULL
</literal>,
17061 behaves identically to
<literal>jsonb_set
</literal>. Otherwise behaves
17062 according to the value
17063 of
<parameter>null_value_treatment
</parameter> which must be one
17064 of
<literal>'raise_exception'
</literal>,
17065 <literal>'use_json_null'
</literal>,
<literal>'delete_key'
</literal>, or
17066 <literal>'return_target'
</literal>. The default is
17067 <literal>'use_json_null'
</literal>.
17070 <literal>jsonb_set_lax('[{
"f1":
1,
"f2":null},
2,null,
3]', '{
0,f1}', null)
</literal>
17071 <returnvalue>[{
"f1": null,
"f2": null},
2, null,
3]
</returnvalue>
17074 <literal>jsonb_set_lax('[{
"f1":
99,
"f2":null},
2]', '{
0,f3}', null, true, 'return_target')
</literal>
17075 <returnvalue>[{
"f1":
99,
"f2": null},
2]
</returnvalue>
17080 <entry role=
"func_table_entry"><para role=
"func_signature">
17082 <primary>jsonb_insert
</primary>
17084 <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> )
17085 <returnvalue>jsonb
</returnvalue>
17088 Returns
<parameter>target
</parameter>
17089 with
<parameter>new_value
</parameter> inserted. If the item
17090 designated by the
<parameter>path
</parameter> is an array
17091 element,
<parameter>new_value
</parameter> will be inserted before
17092 that item if
<parameter>insert_after
</parameter> is false (which
17093 is the default), or after it
17094 if
<parameter>insert_after
</parameter> is true. If the item
17095 designated by the
<parameter>path
</parameter> is an object
17096 field,
<parameter>new_value
</parameter> will be inserted only if
17097 the object does not already contain that key.
17098 All earlier steps in the path must exist, or
17099 the
<parameter>target
</parameter> is returned unchanged.
17100 As with the path oriented operators, negative integers that
17101 appear in the
<parameter>path
</parameter> count from the end
17103 If the last path step is an array index that is out of range, the new
17104 value is added at the beginning of the array if the index is negative,
17105 or at the end of the array if it is positive.
17108 <literal>jsonb_insert('{
"a": [
0,
1,
2]}', '{a,
1}', '
"new_value"')
</literal>
17109 <returnvalue>{
"a": [
0,
"new_value",
1,
2]}
</returnvalue>
17112 <literal>jsonb_insert('{
"a": [
0,
1,
2]}', '{a,
1}', '
"new_value"', true)
</literal>
17113 <returnvalue>{
"a": [
0,
1,
"new_value",
2]}
</returnvalue>
17118 <entry role=
"func_table_entry"><para role=
"func_signature">
17120 <primary>json_strip_nulls
</primary>
17122 <function>json_strip_nulls
</function> (
<type>json
</type> )
17123 <returnvalue>json
</returnvalue>
17125 <para role=
"func_signature">
17127 <primary>jsonb_strip_nulls
</primary>
17129 <function>jsonb_strip_nulls
</function> (
<type>jsonb
</type> )
17130 <returnvalue>jsonb
</returnvalue>
17133 Deletes all object fields that have null values from the given JSON
17134 value, recursively. Null values that are not object fields are
17138 <literal>json_strip_nulls('[{
"f1":
1,
"f2":null},
2, null,
3]')
</literal>
17139 <returnvalue>[{
"f1":
1},
2,null,
3]
</returnvalue>
17144 <entry role=
"func_table_entry"><para role=
"func_signature">
17146 <primary>jsonb_path_exists
</primary>
17148 <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> )
17149 <returnvalue>boolean
</returnvalue>
17152 Checks whether the JSON path returns any item for the specified JSON
17154 (This is useful only with SQL-standard JSON path expressions, not
17155 <link linkend=
"functions-sqljson-check-expressions">predicate check
17156 expressions
</link>, since those always return a value.)
17157 If the
<parameter>vars
</parameter> argument is specified, it must
17158 be a JSON object, and its fields provide named values to be
17159 substituted into the
<type>jsonpath
</type> expression.
17160 If the
<parameter>silent
</parameter> argument is specified and
17161 is
<literal>true
</literal>, the function suppresses the same errors
17162 as the
<literal>@?
</literal> and
<literal>@@
</literal> operators do.
17165 <literal>jsonb_path_exists('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17166 <returnvalue>t
</returnvalue>
17171 <entry role=
"func_table_entry"><para role=
"func_signature">
17173 <primary>jsonb_path_match
</primary>
17175 <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> )
17176 <returnvalue>boolean
</returnvalue>
17179 Returns the result of a JSON path predicate check for the specified
17181 (This is useful only
17182 with
<link linkend=
"functions-sqljson-check-expressions">predicate
17183 check expressions
</link>, not SQL-standard JSON path expressions,
17184 since it will either fail or return
<literal>NULL
</literal> if the
17185 path result is not a single boolean value.)
17186 The optional
<parameter>vars
</parameter>
17187 and
<parameter>silent
</parameter> arguments act the same as
17188 for
<function>jsonb_path_exists
</function>.
17191 <literal>jsonb_path_match('{
"a":[
1,
2,
3,
4,
5]}', 'exists($.a[*] ? (@
>= $min
&& @
<= $max))', '{
"min":
2,
"max":
4}')
</literal>
17192 <returnvalue>t
</returnvalue>
17197 <entry role=
"func_table_entry"><para role=
"func_signature">
17199 <primary>jsonb_path_query
</primary>
17201 <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> )
17202 <returnvalue>setof jsonb
</returnvalue>
17205 Returns all JSON items returned by the JSON path for the specified
17207 For SQL-standard JSON path expressions it returns the JSON
17208 values selected from
<parameter>target
</parameter>.
17209 For
<link linkend=
"functions-sqljson-check-expressions">predicate
17210 check expressions
</link> it returns the result of the predicate
17211 check:
<literal>true
</literal>,
<literal>false
</literal>,
17212 or
<literal>null
</literal>.
17213 The optional
<parameter>vars
</parameter>
17214 and
<parameter>silent
</parameter> arguments act the same as
17215 for
<function>jsonb_path_exists
</function>.
17218 <literal>select * from jsonb_path_query('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17219 <returnvalue></returnvalue>
17231 <entry role=
"func_table_entry"><para role=
"func_signature">
17233 <primary>jsonb_path_query_array
</primary>
17235 <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> )
17236 <returnvalue>jsonb
</returnvalue>
17239 Returns all JSON items returned by the JSON path for the specified
17240 JSON value, as a JSON array.
17241 The parameters are the same as
17242 for
<function>jsonb_path_query
</function>.
17245 <literal>jsonb_path_query_array('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17246 <returnvalue>[
2,
3,
4]
</returnvalue>
17251 <entry role=
"func_table_entry"><para role=
"func_signature">
17253 <primary>jsonb_path_query_first
</primary>
17255 <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> )
17256 <returnvalue>jsonb
</returnvalue>
17259 Returns the first JSON item returned by the JSON path for the
17260 specified JSON value, or
<literal>NULL
</literal> if there are no
17262 The parameters are the same as
17263 for
<function>jsonb_path_query
</function>.
17266 <literal>jsonb_path_query_first('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17267 <returnvalue>2</returnvalue>
17272 <entry role=
"func_table_entry"><para role=
"func_signature">
17274 <primary>jsonb_path_exists_tz
</primary>
17276 <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> )
17277 <returnvalue>boolean
</returnvalue>
17279 <para role=
"func_signature">
17281 <primary>jsonb_path_match_tz
</primary>
17283 <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> )
17284 <returnvalue>boolean
</returnvalue>
17286 <para role=
"func_signature">
17288 <primary>jsonb_path_query_tz
</primary>
17290 <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> )
17291 <returnvalue>setof jsonb
</returnvalue>
17293 <para role=
"func_signature">
17295 <primary>jsonb_path_query_array_tz
</primary>
17297 <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> )
17298 <returnvalue>jsonb
</returnvalue>
17300 <para role=
"func_signature">
17302 <primary>jsonb_path_query_first_tz
</primary>
17304 <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> )
17305 <returnvalue>jsonb
</returnvalue>
17308 These functions act like their counterparts described above without
17309 the
<literal>_tz
</literal> suffix, except that these functions support
17310 comparisons of date/time values that require timezone-aware
17311 conversions. The example below requires interpretation of the
17312 date-only value
<literal>2015-
08-
02</literal> as a timestamp with time
17313 zone, so the result depends on the current
17314 <xref linkend=
"guc-timezone"/> setting. Due to this dependency, these
17315 functions are marked as stable, which means these functions cannot be
17316 used in indexes. Their counterparts are immutable, and so can be used
17317 in indexes; but they will throw errors if asked to make such
17321 <literal>jsonb_path_exists_tz('[
"2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime()
< "2015-08-02".datetime())')
</literal>
17322 <returnvalue>t
</returnvalue>
17327 <entry role=
"func_table_entry"><para role=
"func_signature">
17329 <primary>jsonb_pretty
</primary>
17331 <function>jsonb_pretty
</function> (
<type>jsonb
</type> )
17332 <returnvalue>text
</returnvalue>
17335 Converts the given JSON value to pretty-printed, indented text.
17338 <literal>jsonb_pretty('[{
"f1":
1,
"f2":null},
2]')
</literal>
17339 <returnvalue></returnvalue>
17353 <entry role=
"func_table_entry"><para role=
"func_signature">
17355 <primary>json_typeof
</primary>
17357 <function>json_typeof
</function> (
<type>json
</type> )
17358 <returnvalue>text
</returnvalue>
17360 <para role=
"func_signature">
17362 <primary>jsonb_typeof
</primary>
17364 <function>jsonb_typeof
</function> (
<type>jsonb
</type> )
17365 <returnvalue>text
</returnvalue>
17368 Returns the type of the top-level JSON value as a text string.
17370 <literal>object
</literal>,
<literal>array
</literal>,
17371 <literal>string
</literal>,
<literal>number
</literal>,
17372 <literal>boolean
</literal>, and
<literal>null
</literal>.
17373 (The
<literal>null
</literal> result should not be confused
17374 with an SQL NULL; see the examples.)
17377 <literal>json_typeof('-
123.4')
</literal>
17378 <returnvalue>number
</returnvalue>
17381 <literal>json_typeof('null'::json)
</literal>
17382 <returnvalue>null
</returnvalue>
17385 <literal>json_typeof(NULL::json) IS NULL
</literal>
17386 <returnvalue>t
</returnvalue>
17394 <sect2 id=
"functions-sqljson-path">
17395 <title>The SQL/JSON Path Language
</title>
17397 <indexterm zone=
"functions-sqljson-path">
17398 <primary>SQL/JSON path language
</primary>
17402 SQL/JSON path expressions specify item(s) to be retrieved
17403 from a JSON value, similarly to XPath expressions used
17404 for access to XML content. In
<productname>PostgreSQL
</productname>,
17405 path expressions are implemented as the
<type>jsonpath
</type>
17406 data type and can use any elements described in
17407 <xref linkend=
"datatype-jsonpath"/>.
17411 JSON query functions and operators
17412 pass the provided path expression to the
<firstterm>path engine
</firstterm>
17413 for evaluation. If the expression matches the queried JSON data,
17414 the corresponding JSON item, or set of items, is returned.
17415 If there is no match, the result will be
<literal>NULL
</literal>,
17416 <literal>false
</literal>, or an error, depending on the function.
17417 Path expressions are written in the SQL/JSON path language
17418 and can include arithmetic expressions and functions.
17422 A path expression consists of a sequence of elements allowed
17423 by the
<type>jsonpath
</type> data type.
17424 The path expression is normally evaluated from left to right, but
17425 you can use parentheses to change the order of operations.
17426 If the evaluation is successful, a sequence of JSON items is produced,
17427 and the evaluation result is returned to the JSON query function
17428 that completes the specified computation.
17432 To refer to the JSON value being queried (the
17433 <firstterm>context item
</firstterm>), use the
<literal>$
</literal> variable
17434 in the path expression. The first element of a path must always
17435 be
<literal>$
</literal>. It can be followed by one or more
17436 <link linkend=
"type-jsonpath-accessors">accessor operators
</link>,
17437 which go down the JSON structure level by level to retrieve sub-items
17438 of the context item. Each accessor operator acts on the
17439 result(s) of the previous evaluation step, producing zero, one, or more
17440 output items from each input item.
17444 For example, suppose you have some JSON data from a GPS tracker that you
17445 would like to parse, such as:
17451 "location": [
47.763,
13.4034 ],
17452 "start time":
"2018-10-14 10:05:14",
17456 "location": [
47.706,
13.2635 ],
17457 "start time":
"2018-10-14 10:39:21",
17464 (The above example can be copied-and-pasted
17465 into
<application>psql
</application> to set things up for the following
17466 examples. Then
<application>psql
</application> will
17467 expand
<literal>:'json'
</literal> into a suitably-quoted string
17468 constant containing the JSON value.)
17472 To retrieve the available track segments, you need to use the
17473 <literal>.
<replaceable>key
</replaceable></literal> accessor
17474 operator to descend through surrounding JSON objects, for example:
17476 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments');
</userinput>
17478 -----------------------------------------------------------
&zwsp;-----------------------------------------------------------
&zwsp;---------------------------------------------
17479 [{
"HR":
73,
"location": [
47.763,
13.4034],
"start time":
"2018-10-14 10:05:14"}, {
"HR":
135,
"location": [
47.706,
13.2635],
"start time":
"2018-10-14 10:39:21"}]
17484 To retrieve the contents of an array, you typically use the
17485 <literal>[*]
</literal> operator.
17486 The following example will return the location coordinates for all
17487 the available track segments:
17489 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].location');
</userinput>
17491 -------------------
17495 Here we started with the whole JSON input value (
<literal>$
</literal>),
17496 then the
<literal>.track
</literal> accessor selected the JSON object
17497 associated with the
<literal>"track"</literal> object key, then
17498 the
<literal>.segments
</literal> accessor selected the JSON array
17499 associated with the
<literal>"segments"</literal> key within that
17500 object, then the
<literal>[*]
</literal> accessor selected each element
17501 of that array (producing a series of items), then
17502 the
<literal>.location
</literal> accessor selected the JSON array
17503 associated with the
<literal>"location"</literal> key within each of
17504 those objects. In this example, each of those objects had
17505 a
<literal>"location"</literal> key; but if any of them did not,
17506 the
<literal>.location
</literal> accessor would have simply produced no
17507 output for that input item.
17511 To return the coordinates of the first segment only, you can
17512 specify the corresponding subscript in the
<literal>[]
</literal>
17513 accessor operator. Recall that JSON array indexes are
0-relative:
17515 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[
0].location');
</userinput>
17517 -------------------
17523 The result of each path evaluation step can be processed
17524 by one or more of the
<type>jsonpath
</type> operators and methods
17525 listed in
<xref linkend=
"functions-sqljson-path-operators"/>.
17526 Each method name must be preceded by a dot. For example,
17527 you can get the size of an array:
17529 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments.size()');
</userinput>
17534 More examples of using
<type>jsonpath
</type> operators
17535 and methods within path expressions appear below in
17536 <xref linkend=
"functions-sqljson-path-operators"/>.
17540 A path can also contain
17541 <firstterm>filter expressions
</firstterm> that work similarly to the
17542 <literal>WHERE
</literal> clause in SQL. A filter expression begins with
17543 a question mark and provides a condition in parentheses:
17546 ? (
<replaceable>condition
</replaceable>)
17551 Filter expressions must be written just after the path evaluation step
17552 to which they should apply. The result of that step is filtered to include
17553 only those items that satisfy the provided condition. SQL/JSON defines
17554 three-valued logic, so the condition can
17555 produce
<literal>true
</literal>,
<literal>false
</literal>,
17556 or
<literal>unknown
</literal>. The
<literal>unknown
</literal> value
17557 plays the same role as SQL
<literal>NULL
</literal> and can be tested
17558 for with the
<literal>is unknown
</literal> predicate. Further path
17559 evaluation steps use only those items for which the filter expression
17560 returned
<literal>true
</literal>.
17564 The functions and operators that can be used in filter expressions are
17565 listed in
<xref linkend=
"functions-sqljson-filter-ex-table"/>. Within a
17566 filter expression, the
<literal>@
</literal> variable denotes the value
17567 being considered (i.e., one result of the preceding path step). You can
17568 write accessor operators after
<literal>@
</literal> to retrieve component
17573 For example, suppose you would like to retrieve all heart rate values higher
17574 than
130. You can achieve this as follows:
17576 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].HR ? (@
> 130)');
</userinput>
17584 To get the start times of segments with such values, you have to
17585 filter out irrelevant segments before selecting the start times, so the
17586 filter expression is applied to the previous step, and the path used
17587 in the condition is different:
17589 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.HR
> 130).
"start time"');
</userinput>
17591 -----------------------
17592 "2018-10-14 10:39:21"
17597 You can use several filter expressions in sequence, if required.
17598 The following example selects start times of all segments that
17599 contain locations with relevant coordinates and high heart rate values:
17601 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[
1]
< 13.4) ? (@.HR
> 130).
"start time"');
</userinput>
17603 -----------------------
17604 "2018-10-14 10:39:21"
17609 Using filter expressions at different nesting levels is also allowed.
17610 The following example first filters all segments by location, and then
17611 returns high heart rate values for these segments, if available:
17613 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[
1]
< 13.4).HR ? (@
> 130)');
</userinput>
17621 You can also nest filter expressions within each other.
17622 This example returns the size of the track if it contains any
17623 segments with high heart rate values, or an empty sequence otherwise:
17625 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track ? (exists(@.segments[*] ? (@.HR
> 130))).segments.size()');
</userinput>
17632 <sect3 id=
"functions-sqljson-deviations">
17633 <title>Deviations from the SQL Standard
</title>
17635 <productname>PostgreSQL
</productname>'s implementation of the SQL/JSON path
17636 language has the following deviations from the SQL/JSON standard.
17639 <sect4 id=
"functions-sqljson-check-expressions">
17640 <title>Boolean Predicate Check Expressions
</title>
17642 As an extension to the SQL standard,
17643 a
<productname>PostgreSQL
</productname> path expression can be a
17644 Boolean predicate, whereas the SQL standard allows predicates only within
17645 filters. While SQL-standard path expressions return the relevant
17646 element(s) of the queried JSON value, predicate check expressions
17647 return the single three-valued result of the
17648 predicate:
<literal>true
</literal>,
17649 <literal>false
</literal>, or
<literal>unknown
</literal>.
17650 For example, we could write this SQL-standard filter expression:
17652 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments ?(@[*].HR
> 130)');
</userinput>
17654 -----------------------------------------------------------
&zwsp;----------------------
17655 {
"HR":
135,
"location": [
47.706,
13.2635],
"start time":
"2018-10-14 10:39:21"}
17657 The similar predicate check expression simply
17658 returns
<literal>true
</literal>, indicating that a match exists:
17660 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].HR
> 130');
</userinput>
17669 Predicate check expressions are required in the
17670 <literal>@@
</literal> operator (and the
17671 <function>jsonb_path_match
</function> function), and should not be used
17672 with the
<literal>@?
</literal> operator (or the
17673 <function>jsonb_path_exists
</function> function).
17678 <sect4 id=
"functions-sqljson-regular-expression-deviation">
17679 <title>Regular Expression Interpretation
</title>
17681 There are minor differences in the interpretation of regular
17682 expression patterns used in
<literal>like_regex
</literal> filters, as
17683 described in
<xref linkend=
"jsonpath-regular-expressions"/>.
17688 <sect3 id=
"functions-sqljson-strict-and-lax-modes">
17689 <title>Strict and Lax Modes
</title>
17691 When you query JSON data, the path expression may not match the
17692 actual JSON data structure. An attempt to access a non-existent
17693 member of an object or element of an array is defined as a
17694 structural error. SQL/JSON path expressions have two modes
17695 of handling structural errors:
17701 lax (default)
— the path engine implicitly adapts
17702 the queried data to the specified path.
17703 Any structural errors that cannot be fixed as described below
17704 are suppressed, producing no match.
17709 strict
— if a structural error occurs, an error is raised.
17715 Lax mode facilitates matching of a JSON document and path
17716 expression when the JSON data does not conform to the expected schema.
17717 If an operand does not match the requirements of a particular operation,
17718 it can be automatically wrapped as an SQL/JSON array, or unwrapped by
17719 converting its elements into an SQL/JSON sequence before performing
17720 the operation. Also, comparison operators automatically unwrap their
17721 operands in lax mode, so you can compare SQL/JSON arrays
17722 out-of-the-box. An array of size
1 is considered equal to its sole element.
17723 Automatic unwrapping is not performed when:
17727 The path expression contains
<literal>type()
</literal> or
17728 <literal>size()
</literal> methods that return the type
17729 and the number of elements in the array, respectively.
17734 The queried JSON data contain nested arrays. In this case, only
17735 the outermost array is unwrapped, while all the inner arrays
17736 remain unchanged. Thus, implicit unwrapping can only go one
17737 level down within each path evaluation step.
17744 For example, when querying the GPS data listed above, you can
17745 abstract from the fact that it stores an array of segments
17746 when using lax mode:
17748 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments.location');
</userinput>
17750 -------------------
17757 In strict mode, the specified path must exactly match the structure of
17758 the queried JSON document, so using this path
17759 expression will cause an error:
17761 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments.location');
</userinput>
17762 ERROR: jsonpath member accessor can only be applied to an object
17764 To get the same result as in lax mode, you have to explicitly unwrap the
17765 <literal>segments
</literal> array:
17767 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments[*].location');
</userinput>
17769 -------------------
17776 The unwrapping behavior of lax mode can lead to surprising results. For
17777 instance, the following query using the
<literal>.**
</literal> accessor
17778 selects every
<literal>HR
</literal> value twice:
17780 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.**.HR');
</userinput>
17788 This happens because the
<literal>.**
</literal> accessor selects both
17789 the
<literal>segments
</literal> array and each of its elements, while
17790 the
<literal>.HR
</literal> accessor automatically unwraps arrays when
17791 using lax mode. To avoid surprising results, we recommend using
17792 the
<literal>.**
</literal> accessor only in strict mode. The
17793 following query selects each
<literal>HR
</literal> value just once:
17795 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.**.HR');
</userinput>
17804 The unwrapping of arrays can also lead to unexpected results. Consider this
17805 example, which selects all the
<literal>location
</literal> arrays:
17807 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments[*].location');
</userinput>
17809 -------------------
17814 As expected it returns the full arrays. But applying a filter expression
17815 causes the arrays to be unwrapped to evaluate each item, returning only the
17816 items that match the expression:
17818 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments[*].location ?(@[*]
> 15)');
</userinput>
17825 This despite the fact that the full arrays are selected by the path
17826 expression. Use strict mode to restore selecting the arrays:
17828 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments[*].location ?(@[*]
> 15)');
</userinput>
17830 -------------------
17838 <sect3 id=
"functions-sqljson-path-operators">
17839 <title>SQL/JSON Path Operators and Methods
</title>
17842 <xref linkend=
"functions-sqljson-op-table"/> shows the operators and
17843 methods available in
<type>jsonpath
</type>. Note that while the unary
17844 operators and methods can be applied to multiple values resulting from a
17845 preceding path step, the binary operators (addition etc.) can only be
17846 applied to single values. In lax mode, methods applied to an array will be
17847 executed for each value in the array. The exceptions are
17848 <literal>.type()
</literal> and
<literal>.size()
</literal>, which apply to
17852 <table id=
"functions-sqljson-op-table">
17853 <title><type>jsonpath
</type> Operators and Methods
</title>
17857 <entry role=
"func_table_entry"><para role=
"func_signature">
17871 <entry role=
"func_table_entry"><para role=
"func_signature">
17872 <replaceable>number
</replaceable> <literal>+
</literal> <replaceable>number
</replaceable>
17873 <returnvalue><replaceable>number
</replaceable></returnvalue>
17879 <literal>jsonb_path_query('[
2]', '$[
0] +
3')
</literal>
17880 <returnvalue>5</returnvalue>
17885 <entry role=
"func_table_entry"><para role=
"func_signature">
17886 <literal>+
</literal> <replaceable>number
</replaceable>
17887 <returnvalue><replaceable>number
</replaceable></returnvalue>
17890 Unary plus (no operation); unlike addition, this can iterate over
17894 <literal>jsonb_path_query_array('{
"x": [
2,
3,
4]}', '+ $.x')
</literal>
17895 <returnvalue>[
2,
3,
4]
</returnvalue>
17900 <entry role=
"func_table_entry"><para role=
"func_signature">
17901 <replaceable>number
</replaceable> <literal>-
</literal> <replaceable>number
</replaceable>
17902 <returnvalue><replaceable>number
</replaceable></returnvalue>
17908 <literal>jsonb_path_query('[
2]', '
7 - $[
0]')
</literal>
17909 <returnvalue>5</returnvalue>
17914 <entry role=
"func_table_entry"><para role=
"func_signature">
17915 <literal>-
</literal> <replaceable>number
</replaceable>
17916 <returnvalue><replaceable>number
</replaceable></returnvalue>
17919 Negation; unlike subtraction, this can iterate over
17923 <literal>jsonb_path_query_array('{
"x": [
2,
3,
4]}', '- $.x')
</literal>
17924 <returnvalue>[-
2, -
3, -
4]
</returnvalue>
17929 <entry role=
"func_table_entry"><para role=
"func_signature">
17930 <replaceable>number
</replaceable> <literal>*
</literal> <replaceable>number
</replaceable>
17931 <returnvalue><replaceable>number
</replaceable></returnvalue>
17937 <literal>jsonb_path_query('[
4]', '
2 * $[
0]')
</literal>
17938 <returnvalue>8</returnvalue>
17943 <entry role=
"func_table_entry"><para role=
"func_signature">
17944 <replaceable>number
</replaceable> <literal>/
</literal> <replaceable>number
</replaceable>
17945 <returnvalue><replaceable>number
</replaceable></returnvalue>
17951 <literal>jsonb_path_query('[
8.5]', '$[
0] /
2')
</literal>
17952 <returnvalue>4.2500000000000000</returnvalue>
17957 <entry role=
"func_table_entry"><para role=
"func_signature">
17958 <replaceable>number
</replaceable> <literal>%
</literal> <replaceable>number
</replaceable>
17959 <returnvalue><replaceable>number
</replaceable></returnvalue>
17965 <literal>jsonb_path_query('[
32]', '$[
0] %
10')
</literal>
17966 <returnvalue>2</returnvalue>
17971 <entry role=
"func_table_entry"><para role=
"func_signature">
17972 <replaceable>value
</replaceable> <literal>.
</literal> <literal>type()
</literal>
17973 <returnvalue><replaceable>string
</replaceable></returnvalue>
17976 Type of the JSON item (see
<function>json_typeof
</function>)
17979 <literal>jsonb_path_query_array('[
1,
"2", {}]', '$[*].type()')
</literal>
17980 <returnvalue>[
"number",
"string",
"object"]
</returnvalue>
17985 <entry role=
"func_table_entry"><para role=
"func_signature">
17986 <replaceable>value
</replaceable> <literal>.
</literal> <literal>size()
</literal>
17987 <returnvalue><replaceable>number
</replaceable></returnvalue>
17990 Size of the JSON item (number of array elements, or
1 if not an
17994 <literal>jsonb_path_query('{
"m": [
11,
15]}', '$.m.size()')
</literal>
17995 <returnvalue>2</returnvalue>
18000 <entry role=
"func_table_entry"><para role=
"func_signature">
18001 <replaceable>value
</replaceable> <literal>.
</literal> <literal>boolean()
</literal>
18002 <returnvalue><replaceable>boolean
</replaceable></returnvalue>
18005 Boolean value converted from a JSON boolean, number, or string
18008 <literal>jsonb_path_query_array('[
1,
"yes", false]', '$[*].boolean()')
</literal>
18009 <returnvalue>[true, true, false]
</returnvalue>
18014 <entry role=
"func_table_entry"><para role=
"func_signature">
18015 <replaceable>value
</replaceable> <literal>.
</literal> <literal>string()
</literal>
18016 <returnvalue><replaceable>string
</replaceable></returnvalue>
18019 String value converted from a JSON boolean, number, string, or
18020 datetime (the output format for datetimes is determined by
18021 the
<xref linkend=
"guc-datestyle"/> parameter)
18024 <literal>jsonb_path_query_array('[
1.23,
"xyz", false]', '$[*].string()')
</literal>
18025 <returnvalue>[
"1.23",
"xyz",
"false"]
</returnvalue>
18028 <literal>jsonb_path_query('
"2023-08-15"', '$.datetime().string()')
</literal>
18029 <returnvalue>"2023-08-15"</returnvalue>
18034 <entry role=
"func_table_entry"><para role=
"func_signature">
18035 <replaceable>value
</replaceable> <literal>.
</literal> <literal>double()
</literal>
18036 <returnvalue><replaceable>number
</replaceable></returnvalue>
18039 Approximate floating-point number converted from a JSON number or
18043 <literal>jsonb_path_query('{
"len":
"1.9"}', '$.len.double() *
2')
</literal>
18044 <returnvalue>3.8</returnvalue>
18049 <entry role=
"func_table_entry"><para role=
"func_signature">
18050 <replaceable>number
</replaceable> <literal>.
</literal> <literal>ceiling()
</literal>
18051 <returnvalue><replaceable>number
</replaceable></returnvalue>
18054 Nearest integer greater than or equal to the given number
18057 <literal>jsonb_path_query('{
"h":
1.3}', '$.h.ceiling()')
</literal>
18058 <returnvalue>2</returnvalue>
18063 <entry role=
"func_table_entry"><para role=
"func_signature">
18064 <replaceable>number
</replaceable> <literal>.
</literal> <literal>floor()
</literal>
18065 <returnvalue><replaceable>number
</replaceable></returnvalue>
18068 Nearest integer less than or equal to the given number
18071 <literal>jsonb_path_query('{
"h":
1.7}', '$.h.floor()')
</literal>
18072 <returnvalue>1</returnvalue>
18077 <entry role=
"func_table_entry"><para role=
"func_signature">
18078 <replaceable>number
</replaceable> <literal>.
</literal> <literal>abs()
</literal>
18079 <returnvalue><replaceable>number
</replaceable></returnvalue>
18082 Absolute value of the given number
18085 <literal>jsonb_path_query('{
"z": -
0.3}', '$.z.abs()')
</literal>
18086 <returnvalue>0.3</returnvalue>
18091 <entry role=
"func_table_entry"><para role=
"func_signature">
18092 <replaceable>value
</replaceable> <literal>.
</literal> <literal>bigint()
</literal>
18093 <returnvalue><replaceable>bigint
</replaceable></returnvalue>
18096 Big integer value converted from a JSON number or string
18099 <literal>jsonb_path_query('{
"len":
"9876543219"}', '$.len.bigint()')
</literal>
18100 <returnvalue>9876543219</returnvalue>
18105 <entry role=
"func_table_entry"><para role=
"func_signature">
18106 <replaceable>value
</replaceable> <literal>.
</literal> <literal>decimal( [
<replaceable>precision
</replaceable> [ ,
<replaceable>scale
</replaceable> ] ] )
</literal>
18107 <returnvalue><replaceable>decimal
</replaceable></returnvalue>
18110 Rounded decimal value converted from a JSON number or string
18111 (
<literal>precision
</literal> and
<literal>scale
</literal> must be
18115 <literal>jsonb_path_query('
1234.5678', '$.decimal(
6,
2)')
</literal>
18116 <returnvalue>1234.57</returnvalue>
18121 <entry role=
"func_table_entry"><para role=
"func_signature">
18122 <replaceable>value
</replaceable> <literal>.
</literal> <literal>integer()
</literal>
18123 <returnvalue><replaceable>integer
</replaceable></returnvalue>
18126 Integer value converted from a JSON number or string
18129 <literal>jsonb_path_query('{
"len":
"12345"}', '$.len.integer()')
</literal>
18130 <returnvalue>12345</returnvalue>
18135 <entry role=
"func_table_entry"><para role=
"func_signature">
18136 <replaceable>value
</replaceable> <literal>.
</literal> <literal>number()
</literal>
18137 <returnvalue><replaceable>numeric
</replaceable></returnvalue>
18140 Numeric value converted from a JSON number or string
18143 <literal>jsonb_path_query('{
"len":
"123.45"}', '$.len.number()')
</literal>
18144 <returnvalue>123.45</returnvalue>
18149 <entry role=
"func_table_entry"><para role=
"func_signature">
18150 <replaceable>string
</replaceable> <literal>.
</literal> <literal>datetime()
</literal>
18151 <returnvalue><replaceable>datetime_type
</replaceable></returnvalue>
18155 Date/time value converted from a string
18158 <literal>jsonb_path_query('[
"2015-8-1",
"2015-08-12"]', '$[*] ? (@.datetime()
< "2015-08-2".datetime())')
</literal>
18159 <returnvalue>"2015-8-1"</returnvalue>
18164 <entry role=
"func_table_entry"><para role=
"func_signature">
18165 <replaceable>string
</replaceable> <literal>.
</literal> <literal>datetime(
<replaceable>template
</replaceable>)
</literal>
18166 <returnvalue><replaceable>datetime_type
</replaceable></returnvalue>
18170 Date/time value converted from a string using the
18171 specified
<function>to_timestamp
</function> template
18174 <literal>jsonb_path_query_array('[
"12:30",
"18:40"]', '$[*].datetime(
"HH24:MI")')
</literal>
18175 <returnvalue>[
"12:30:00",
"18:40:00"]
</returnvalue>
18180 <entry role=
"func_table_entry"><para role=
"func_signature">
18181 <replaceable>string
</replaceable> <literal>.
</literal> <literal>date()
</literal>
18182 <returnvalue><replaceable>date
</replaceable></returnvalue>
18185 Date value converted from a string
18188 <literal>jsonb_path_query('
"2023-08-15"', '$.date()')
</literal>
18189 <returnvalue>"2023-08-15"</returnvalue>
18194 <entry role=
"func_table_entry"><para role=
"func_signature">
18195 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time()
</literal>
18196 <returnvalue><replaceable>time without time zone
</replaceable></returnvalue>
18199 Time without time zone value converted from a string
18202 <literal>jsonb_path_query('
"12:34:56"', '$.time()')
</literal>
18203 <returnvalue>"12:34:56"</returnvalue>
18208 <entry role=
"func_table_entry"><para role=
"func_signature">
18209 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time(
<replaceable>precision
</replaceable>)
</literal>
18210 <returnvalue><replaceable>time without time zone
</replaceable></returnvalue>
18213 Time without time zone value converted from a string, with fractional
18214 seconds adjusted to the given precision
18217 <literal>jsonb_path_query('
"12:34:56.789"', '$.time(
2)')
</literal>
18218 <returnvalue>"12:34:56.79"</returnvalue>
18223 <entry role=
"func_table_entry"><para role=
"func_signature">
18224 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time_tz()
</literal>
18225 <returnvalue><replaceable>time with time zone
</replaceable></returnvalue>
18228 Time with time zone value converted from a string
18231 <literal>jsonb_path_query('
"12:34:56 +05:30"', '$.time_tz()')
</literal>
18232 <returnvalue>"12:34:56+05:30"</returnvalue>
18237 <entry role=
"func_table_entry"><para role=
"func_signature">
18238 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time_tz(
<replaceable>precision
</replaceable>)
</literal>
18239 <returnvalue><replaceable>time with time zone
</replaceable></returnvalue>
18242 Time with time zone value converted from a string, with fractional
18243 seconds adjusted to the given precision
18246 <literal>jsonb_path_query('
"12:34:56.789 +05:30"', '$.time_tz(
2)')
</literal>
18247 <returnvalue>"12:34:56.79+05:30"</returnvalue>
18252 <entry role=
"func_table_entry"><para role=
"func_signature">
18253 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp()
</literal>
18254 <returnvalue><replaceable>timestamp without time zone
</replaceable></returnvalue>
18257 Timestamp without time zone value converted from a string
18260 <literal>jsonb_path_query('
"2023-08-15 12:34:56"', '$.timestamp()')
</literal>
18261 <returnvalue>"2023-08-15T12:34:56"</returnvalue>
18266 <entry role=
"func_table_entry"><para role=
"func_signature">
18267 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp(
<replaceable>precision
</replaceable>)
</literal>
18268 <returnvalue><replaceable>timestamp without time zone
</replaceable></returnvalue>
18271 Timestamp without time zone value converted from a string, with
18272 fractional seconds adjusted to the given precision
18275 <literal>jsonb_path_query('
"2023-08-15 12:34:56.789"', '$.timestamp(
2)')
</literal>
18276 <returnvalue>"2023-08-15T12:34:56.79"</returnvalue>
18281 <entry role=
"func_table_entry"><para role=
"func_signature">
18282 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp_tz()
</literal>
18283 <returnvalue><replaceable>timestamp with time zone
</replaceable></returnvalue>
18286 Timestamp with time zone value converted from a string
18289 <literal>jsonb_path_query('
"2023-08-15 12:34:56 +05:30"', '$.timestamp_tz()')
</literal>
18290 <returnvalue>"2023-08-15T12:34:56+05:30"</returnvalue>
18295 <entry role=
"func_table_entry"><para role=
"func_signature">
18296 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp_tz(
<replaceable>precision
</replaceable>)
</literal>
18297 <returnvalue><replaceable>timestamp with time zone
</replaceable></returnvalue>
18300 Timestamp with time zone value converted from a string, with fractional
18301 seconds adjusted to the given precision
18304 <literal>jsonb_path_query('
"2023-08-15 12:34:56.789 +05:30"', '$.timestamp_tz(
2)')
</literal>
18305 <returnvalue>"2023-08-15T12:34:56.79+05:30"</returnvalue>
18310 <entry role=
"func_table_entry"><para role=
"func_signature">
18311 <replaceable>object
</replaceable> <literal>.
</literal> <literal>keyvalue()
</literal>
18312 <returnvalue><replaceable>array
</replaceable></returnvalue>
18315 The object's key-value pairs, represented as an array of objects
18316 containing three fields:
<literal>"key"</literal>,
18317 <literal>"value"</literal>, and
<literal>"id"</literal>;
18318 <literal>"id"</literal> is a unique identifier of the object the
18319 key-value pair belongs to
18322 <literal>jsonb_path_query_array('{
"x":
"20",
"y":
32}', '$.keyvalue()')
</literal>
18323 <returnvalue>[{
"id":
0,
"key":
"x",
"value":
"20"}, {
"id":
0,
"key":
"y",
"value":
32}]
</returnvalue>
18332 The result type of the
<literal>datetime()
</literal> and
18333 <literal>datetime(
<replaceable>template
</replaceable>)
</literal>
18334 methods can be
<type>date
</type>,
<type>timetz
</type>,
<type>time
</type>,
18335 <type>timestamptz
</type>, or
<type>timestamp
</type>.
18336 Both methods determine their result type dynamically.
18339 The
<literal>datetime()
</literal> method sequentially tries to
18340 match its input string to the ISO formats
18341 for
<type>date
</type>,
<type>timetz
</type>,
<type>time
</type>,
18342 <type>timestamptz
</type>, and
<type>timestamp
</type>. It stops on
18343 the first matching format and emits the corresponding data type.
18346 The
<literal>datetime(
<replaceable>template
</replaceable>)
</literal>
18347 method determines the result type according to the fields used in the
18348 provided template string.
18351 The
<literal>datetime()
</literal> and
18352 <literal>datetime(
<replaceable>template
</replaceable>)
</literal> methods
18353 use the same parsing rules as the
<literal>to_timestamp
</literal> SQL
18354 function does (see
<xref linkend=
"functions-formatting"/>), with three
18355 exceptions. First, these methods don't allow unmatched template
18356 patterns. Second, only the following separators are allowed in the
18357 template string: minus sign, period, solidus (slash), comma, apostrophe,
18358 semicolon, colon and space. Third, separators in the template string
18359 must exactly match the input string.
18362 If different date/time types need to be compared, an implicit cast is
18363 applied. A
<type>date
</type> value can be cast to
<type>timestamp
</type>
18364 or
<type>timestamptz
</type>,
<type>timestamp
</type> can be cast to
18365 <type>timestamptz
</type>, and
<type>time
</type> to
<type>timetz
</type>.
18366 However, all but the first of these conversions depend on the current
18367 <xref linkend=
"guc-timezone"/> setting, and thus can only be performed
18368 within timezone-aware
<type>jsonpath
</type> functions. Similarly, other
18369 date/time-related methods that convert strings to date/time types
18370 also do this casting, which may involve the current
18371 <xref linkend=
"guc-timezone"/> setting. Therefore, these conversions can
18372 also only be performed within timezone-aware
<type>jsonpath
</type>
18378 <xref linkend=
"functions-sqljson-filter-ex-table"/> shows the available
18379 filter expression elements.
18382 <table id=
"functions-sqljson-filter-ex-table">
18383 <title><type>jsonpath
</type> Filter Expression Elements
</title>
18387 <entry role=
"func_table_entry"><para role=
"func_signature">
18401 <entry role=
"func_table_entry"><para role=
"func_signature">
18402 <replaceable>value
</replaceable> <literal>==
</literal> <replaceable>value
</replaceable>
18403 <returnvalue>boolean
</returnvalue>
18406 Equality comparison (this, and the other comparison operators, work on
18407 all JSON scalar values)
18410 <literal>jsonb_path_query_array('[
1,
"a",
1,
3]', '$[*] ? (@ ==
1)')
</literal>
18411 <returnvalue>[
1,
1]
</returnvalue>
18414 <literal>jsonb_path_query_array('[
1,
"a",
1,
3]', '$[*] ? (@ ==
"a")')
</literal>
18415 <returnvalue>[
"a"]
</returnvalue>
18420 <entry role=
"func_table_entry"><para role=
"func_signature">
18421 <replaceable>value
</replaceable> <literal>!=
</literal> <replaceable>value
</replaceable>
18422 <returnvalue>boolean
</returnvalue>
18424 <para role=
"func_signature">
18425 <replaceable>value
</replaceable> <literal><></literal> <replaceable>value
</replaceable>
18426 <returnvalue>boolean
</returnvalue>
18429 Non-equality comparison
18432 <literal>jsonb_path_query_array('[
1,
2,
1,
3]', '$[*] ? (@ !=
1)')
</literal>
18433 <returnvalue>[
2,
3]
</returnvalue>
18436 <literal>jsonb_path_query_array('[
"a",
"b",
"c"]', '$[*] ? (@
<> "b")')
</literal>
18437 <returnvalue>[
"a",
"c"]
</returnvalue>
18442 <entry role=
"func_table_entry"><para role=
"func_signature">
18443 <replaceable>value
</replaceable> <literal><</literal> <replaceable>value
</replaceable>
18444 <returnvalue>boolean
</returnvalue>
18447 Less-than comparison
18450 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
< 2)')
</literal>
18451 <returnvalue>[
1]
</returnvalue>
18456 <entry role=
"func_table_entry"><para role=
"func_signature">
18457 <replaceable>value
</replaceable> <literal><=
</literal> <replaceable>value
</replaceable>
18458 <returnvalue>boolean
</returnvalue>
18461 Less-than-or-equal-to comparison
18464 <literal>jsonb_path_query_array('[
"a",
"b",
"c"]', '$[*] ? (@
<=
"b")')
</literal>
18465 <returnvalue>[
"a",
"b"]
</returnvalue>
18470 <entry role=
"func_table_entry"><para role=
"func_signature">
18471 <replaceable>value
</replaceable> <literal>></literal> <replaceable>value
</replaceable>
18472 <returnvalue>boolean
</returnvalue>
18475 Greater-than comparison
18478 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
> 2)')
</literal>
18479 <returnvalue>[
3]
</returnvalue>
18484 <entry role=
"func_table_entry"><para role=
"func_signature">
18485 <replaceable>value
</replaceable> <literal>>=
</literal> <replaceable>value
</replaceable>
18486 <returnvalue>boolean
</returnvalue>
18489 Greater-than-or-equal-to comparison
18492 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
>=
2)')
</literal>
18493 <returnvalue>[
2,
3]
</returnvalue>
18498 <entry role=
"func_table_entry"><para role=
"func_signature">
18499 <literal>true
</literal>
18500 <returnvalue>boolean
</returnvalue>
18503 JSON constant
<literal>true
</literal>
18506 <literal>jsonb_path_query('[{
"name":
"John",
"parent": false}, {
"name":
"Chris",
"parent": true}]', '$[*] ? (@.parent == true)')
</literal>
18507 <returnvalue>{
"name":
"Chris",
"parent": true}
</returnvalue>
18512 <entry role=
"func_table_entry"><para role=
"func_signature">
18513 <literal>false
</literal>
18514 <returnvalue>boolean
</returnvalue>
18517 JSON constant
<literal>false
</literal>
18520 <literal>jsonb_path_query('[{
"name":
"John",
"parent": false}, {
"name":
"Chris",
"parent": true}]', '$[*] ? (@.parent == false)')
</literal>
18521 <returnvalue>{
"name":
"John",
"parent": false}
</returnvalue>
18526 <entry role=
"func_table_entry"><para role=
"func_signature">
18527 <literal>null
</literal>
18528 <returnvalue><replaceable>value
</replaceable></returnvalue>
18531 JSON constant
<literal>null
</literal> (note that, unlike in SQL,
18532 comparison to
<literal>null
</literal> works normally)
18535 <literal>jsonb_path_query('[{
"name":
"Mary",
"job": null}, {
"name":
"Michael",
"job":
"driver"}]', '$[*] ? (@.job == null) .name')
</literal>
18536 <returnvalue>"Mary"</returnvalue>
18541 <entry role=
"func_table_entry"><para role=
"func_signature">
18542 <replaceable>boolean
</replaceable> <literal>&&</literal> <replaceable>boolean
</replaceable>
18543 <returnvalue>boolean
</returnvalue>
18549 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (@
> 1 && @
< 5)')
</literal>
18550 <returnvalue>3</returnvalue>
18555 <entry role=
"func_table_entry"><para role=
"func_signature">
18556 <replaceable>boolean
</replaceable> <literal>||
</literal> <replaceable>boolean
</replaceable>
18557 <returnvalue>boolean
</returnvalue>
18563 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (@
< 1 || @
> 5)')
</literal>
18564 <returnvalue>7</returnvalue>
18569 <entry role=
"func_table_entry"><para role=
"func_signature">
18570 <literal>!
</literal> <replaceable>boolean
</replaceable>
18571 <returnvalue>boolean
</returnvalue>
18577 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (!(@
< 5))')
</literal>
18578 <returnvalue>7</returnvalue>
18583 <entry role=
"func_table_entry"><para role=
"func_signature">
18584 <replaceable>boolean
</replaceable> <literal>is unknown
</literal>
18585 <returnvalue>boolean
</returnvalue>
18588 Tests whether a Boolean condition is
<literal>unknown
</literal>.
18591 <literal>jsonb_path_query('[-
1,
2,
7,
"foo"]', '$[*] ? ((@
> 0) is unknown)')
</literal>
18592 <returnvalue>"foo"</returnvalue>
18597 <entry role=
"func_table_entry"><para role=
"func_signature">
18598 <replaceable>string
</replaceable> <literal>like_regex
</literal> <replaceable>string
</replaceable> <optional> <literal>flag
</literal> <replaceable>string
</replaceable> </optional>
18599 <returnvalue>boolean
</returnvalue>
18602 Tests whether the first operand matches the regular expression
18603 given by the second operand, optionally with modifications
18604 described by a string of
<literal>flag
</literal> characters (see
18605 <xref linkend=
"jsonpath-regular-expressions"/>).
18608 <literal>jsonb_path_query_array('[
"abc",
"abd",
"aBdC",
"abdacb",
"babc"]', '$[*] ? (@ like_regex
"^ab.*c")')
</literal>
18609 <returnvalue>[
"abc",
"abdacb"]
</returnvalue>
18612 <literal>jsonb_path_query_array('[
"abc",
"abd",
"aBdC",
"abdacb",
"babc"]', '$[*] ? (@ like_regex
"^ab.*c" flag
"i")')
</literal>
18613 <returnvalue>[
"abc",
"aBdC",
"abdacb"]
</returnvalue>
18618 <entry role=
"func_table_entry"><para role=
"func_signature">
18619 <replaceable>string
</replaceable> <literal>starts with
</literal> <replaceable>string
</replaceable>
18620 <returnvalue>boolean
</returnvalue>
18623 Tests whether the second operand is an initial substring of the first
18627 <literal>jsonb_path_query('[
"John Smith",
"Mary Stone",
"Bob Johnson"]', '$[*] ? (@ starts with
"John")')
</literal>
18628 <returnvalue>"John Smith"</returnvalue>
18633 <entry role=
"func_table_entry"><para role=
"func_signature">
18634 <literal>exists
</literal> <literal>(
</literal> <replaceable>path_expression
</replaceable> <literal>)
</literal>
18635 <returnvalue>boolean
</returnvalue>
18638 Tests whether a path expression matches at least one SQL/JSON item.
18639 Returns
<literal>unknown
</literal> if the path expression would result
18640 in an error; the second example uses this to avoid a no-such-key error
18644 <literal>jsonb_path_query('{
"x": [
1,
2],
"y": [
2,
4]}', 'strict $.* ? (exists (@ ? (@[*]
> 2)))')
</literal>
18645 <returnvalue>[
2,
4]
</returnvalue>
18648 <literal>jsonb_path_query_array('{
"value":
41}', 'strict $ ? (exists (@.name)) .name')
</literal>
18649 <returnvalue>[]
</returnvalue>
18658 <sect3 id=
"jsonpath-regular-expressions">
18659 <title>SQL/JSON Regular Expressions
</title>
18661 <indexterm zone=
"jsonpath-regular-expressions">
18662 <primary><literal>LIKE_REGEX
</literal></primary>
18663 <secondary>in SQL/JSON
</secondary>
18667 SQL/JSON path expressions allow matching text to a regular expression
18668 with the
<literal>like_regex
</literal> filter. For example, the
18669 following SQL/JSON path query would case-insensitively match all
18670 strings in an array that start with an English vowel:
18672 $[*] ? (@ like_regex
"^[aeiou]" flag
"i")
18677 The optional
<literal>flag
</literal> string may include one or more of
18679 <literal>i
</literal> for case-insensitive match,
18680 <literal>m
</literal> to allow
<literal>^
</literal>
18681 and
<literal>$
</literal> to match at newlines,
18682 <literal>s
</literal> to allow
<literal>.
</literal> to match a newline,
18683 and
<literal>q
</literal> to quote the whole pattern (reducing the
18684 behavior to a simple substring match).
18688 The SQL/JSON standard borrows its definition for regular expressions
18689 from the
<literal>LIKE_REGEX
</literal> operator, which in turn uses the
18690 XQuery standard. PostgreSQL does not currently support the
18691 <literal>LIKE_REGEX
</literal> operator. Therefore,
18692 the
<literal>like_regex
</literal> filter is implemented using the
18693 POSIX regular expression engine described in
18694 <xref linkend=
"functions-posix-regexp"/>. This leads to various minor
18695 discrepancies from standard SQL/JSON behavior, which are cataloged in
18696 <xref linkend=
"posix-vs-xquery"/>.
18697 Note, however, that the flag-letter incompatibilities described there
18698 do not apply to SQL/JSON, as it translates the XQuery flag letters to
18699 match what the POSIX engine expects.
18703 Keep in mind that the pattern argument of
<literal>like_regex
</literal>
18704 is a JSON path string literal, written according to the rules given in
18705 <xref linkend=
"datatype-jsonpath"/>. This means in particular that any
18706 backslashes you want to use in the regular expression must be doubled.
18707 For example, to match string values of the root document that contain
18710 $.* ? (@ like_regex
"^\\d+$")
18716 <sect2 id=
"sqljson-query-functions">
18717 <title>SQL/JSON Query Functions
</title>
18719 SQL/JSON functions
<literal>JSON_EXISTS()
</literal>,
18720 <literal>JSON_QUERY()
</literal>, and
<literal>JSON_VALUE()
</literal>
18721 described in
<xref linkend=
"functions-sqljson-querying"/> can be used
18722 to query JSON documents. Each of these functions apply a
18723 <replaceable>path_expression
</replaceable> (an SQL/JSON path query) to a
18724 <replaceable>context_item
</replaceable> (the document). See
18725 <xref linkend=
"functions-sqljson-path"/> for more details on what
18726 the
<replaceable>path_expression
</replaceable> can contain. The
18727 <replaceable>path_expression
</replaceable> can also reference variables,
18728 whose values are specified with their respective names in the
18729 <literal>PASSING
</literal> clause that is supported by each function.
18730 <replaceable>context_item
</replaceable> can be a
<type>jsonb
</type> value
18731 or a character string that can be successfully cast to
<type>jsonb
</type>.
18734 <table id=
"functions-sqljson-querying">
18735 <title>SQL/JSON Query Functions
</title>
18739 <entry role=
"func_table_entry"><para role=
"func_signature">
18752 <entry role=
"func_table_entry"><para role=
"func_signature">
18753 <indexterm><primary>json_exists
</primary></indexterm>
18755 <function>JSON_EXISTS
</function> (
18756 <replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable>
18757 <optional> <literal>PASSING
</literal> {
<replaceable>value
</replaceable> <literal>AS
</literal> <replaceable>varname
</replaceable> }
<optional>, ...
</optional></optional>
18758 <optional>{
<literal>TRUE
</literal> |
<literal>FALSE
</literal> |
<literal> UNKNOWN
</literal> |
<literal>ERROR
</literal> }
<literal>ON ERROR
</literal> </optional>)
<returnvalue>boolean
</returnvalue>
18764 Returns true if the SQL/JSON
<replaceable>path_expression
</replaceable>
18765 applied to the
<replaceable>context_item
</replaceable> yields any
18766 items, false otherwise.
18771 The
<literal>ON ERROR
</literal> clause specifies the behavior if
18772 an error occurs during
<replaceable>path_expression
</replaceable>
18773 evaluation. Specifying
<literal>ERROR
</literal> will cause an error to
18774 be thrown with the appropriate message. Other options include
18775 returning
<type>boolean
</type> values
<literal>FALSE
</literal> or
18776 <literal>TRUE
</literal> or the value
<literal>UNKNOWN
</literal> which
18777 is actually an SQL NULL. The default when no
<literal>ON ERROR
</literal>
18778 clause is specified is to return the
<type>boolean
</type> value
18779 <literal>FALSE
</literal>.
18787 <literal>JSON_EXISTS(jsonb '{
"key1": [
1,
2,
3]}', 'strict $.key1[*] ? (@
> $x)' PASSING
2 AS x)
</literal>
18788 <returnvalue>t
</returnvalue>
18791 <literal>JSON_EXISTS(jsonb '{
"a": [
1,
2,
3]}', 'lax $.a[
5]' ERROR ON ERROR)
</literal>
18792 <returnvalue>f
</returnvalue>
18795 <literal>JSON_EXISTS(jsonb '{
"a": [
1,
2,
3]}', 'strict $.a[
5]' ERROR ON ERROR)
</literal>
18796 <returnvalue></returnvalue>
18798 ERROR: jsonpath array subscript is out of bounds
18803 <entry role=
"func_table_entry"><para role=
"func_signature">
18804 <indexterm><primary>json_query
</primary></indexterm>
18806 <function>JSON_QUERY
</function> (
18807 <replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable>
18808 <optional> <literal>PASSING
</literal> {
<replaceable>value
</replaceable> <literal>AS
</literal> <replaceable>varname
</replaceable> }
<optional>, ...
</optional></optional>
18809 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>
18810 <optional> {
<literal>WITHOUT
</literal> |
<literal>WITH
</literal> {
<literal>CONDITIONAL
</literal> |
<optional><literal>UNCONDITIONAL
</literal></optional> } }
<optional> <literal>ARRAY
</literal> </optional> <literal>WRAPPER
</literal> </optional>
18811 <optional> {
<literal>KEEP
</literal> |
<literal>OMIT
</literal> }
<literal>QUOTES
</literal> <optional> <literal>ON SCALAR STRING
</literal> </optional> </optional>
18812 <optional> {
<literal>ERROR
</literal> |
<literal>NULL
</literal> |
<literal>EMPTY
</literal> {
<optional> <literal>ARRAY
</literal> </optional> |
<literal>OBJECT
</literal> } |
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable> }
<literal>ON EMPTY
</literal> </optional>
18813 <optional> {
<literal>ERROR
</literal> |
<literal>NULL
</literal> |
<literal>EMPTY
</literal> {
<optional> <literal>ARRAY
</literal> </optional> |
<literal>OBJECT
</literal> } |
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable> }
<literal>ON ERROR
</literal> </optional>)
<returnvalue>jsonb
</returnvalue>
18819 Returns the result of applying the SQL/JSON
18820 <replaceable>path_expression
</replaceable> to the
18821 <replaceable>context_item
</replaceable>.
18826 By default, the result is returned as a value of type
<type>jsonb
</type>,
18827 though the
<literal>RETURNING
</literal> clause can be used to return
18828 as some other type to which it can be successfully coerced.
18833 If the path expression may return multiple values, it might be necessary
18834 to wrap those values using the
<literal>WITH WRAPPER
</literal> clause to
18835 make it a valid JSON string, because the default behavior is to not wrap
18836 them, as if
<literal>WITHOUT WRAPPER
</literal> were specified. The
18837 <literal>WITH WRAPPER
</literal> clause is by default taken to mean
18838 <literal>WITH UNCONDITIONAL WRAPPER
</literal>, which means that even a
18839 single result value will be wrapped. To apply the wrapper only when
18840 multiple values are present, specify
<literal>WITH CONDITIONAL WRAPPER
</literal>.
18841 Getting multiple values in result will be treated as an error if
18842 <literal>WITHOUT WRAPPER
</literal> is specified.
18847 If the result is a scalar string, by default, the returned value will
18848 be surrounded by quotes, making it a valid JSON value. It can be made
18849 explicit by specifying
<literal>KEEP QUOTES
</literal>. Conversely,
18850 quotes can be omitted by specifying
<literal>OMIT QUOTES
</literal>.
18851 To ensure that the result is a valid JSON value,
<literal>OMIT QUOTES
</literal>
18852 cannot be specified when
<literal>WITH WRAPPER
</literal> is also
18858 The
<literal>ON EMPTY
</literal> clause specifies the behavior if
18859 evaluating
<replaceable>path_expression
</replaceable> yields an empty
18860 set. The
<literal>ON ERROR
</literal> clause specifies the behavior
18861 if an error occurs when evaluating
<replaceable>path_expression
</replaceable>,
18862 when coercing the result value to the
<literal>RETURNING
</literal> type,
18863 or when evaluating the
<literal>ON EMPTY
</literal> expression if the
18864 <replaceable>path_expression
</replaceable> evaluation returns an empty
18870 For both
<literal>ON EMPTY
</literal> and
<literal>ON ERROR
</literal>,
18871 specifying
<literal>ERROR
</literal> will cause an error to be thrown with
18872 the appropriate message. Other options include returning an SQL NULL, an
18873 empty array (
<literal>EMPTY
<optional>ARRAY
</optional></literal>),
18874 an empty object (
<literal>EMPTY OBJECT
</literal>), or a user-specified
18875 expression (
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable>)
18876 that can be coerced to jsonb or the type specified in
<literal>RETURNING
</literal>.
18877 The default when
<literal>ON EMPTY
</literal> or
<literal>ON ERROR
</literal>
18878 is not specified is to return an SQL NULL value.
18886 <literal>JSON_QUERY(jsonb '[
1,[
2,
3],null]', 'lax $[*][$off]' PASSING
1 AS off WITH CONDITIONAL WRAPPER)
</literal>
18887 <returnvalue>[
3]
</returnvalue>
18890 <literal>JSON_QUERY(jsonb '{
"a":
"[1, 2]"}', 'lax $.a' OMIT QUOTES)
</literal>
18891 <returnvalue>[
1,
2]
</returnvalue>
18894 <literal>JSON_QUERY(jsonb '{
"a":
"[1, 2]"}', 'lax $.a' RETURNING int[] OMIT QUOTES ERROR ON ERROR)
</literal>
18895 <returnvalue></returnvalue>
18897 ERROR: malformed array literal:
"[1, 2]"
18898 DETAIL: Missing
"]" after array dimensions.
18904 <entry role=
"func_table_entry"><para role=
"func_signature">
18905 <indexterm><primary>json_value
</primary></indexterm>
18907 <function>JSON_VALUE
</function> (
18908 <replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable>
18909 <optional> <literal>PASSING
</literal> {
<replaceable>value
</replaceable> <literal>AS
</literal> <replaceable>varname
</replaceable> }
<optional>, ...
</optional></optional>
18910 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> </optional>
18911 <optional> {
<literal>ERROR
</literal> |
<literal>NULL
</literal> |
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable> }
<literal>ON EMPTY
</literal> </optional>
18912 <optional> {
<literal>ERROR
</literal> |
<literal>NULL
</literal> |
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable> }
<literal>ON ERROR
</literal> </optional>)
<returnvalue>text
</returnvalue>
18918 Returns the result of applying the SQL/JSON
18919 <replaceable>path_expression
</replaceable> to the
18920 <replaceable>context_item
</replaceable>.
18925 Only use
<function>JSON_VALUE()
</function> if the extracted value is
18926 expected to be a single
<acronym>SQL/JSON
</acronym> scalar item;
18927 getting multiple values will be treated as an error. If you expect that
18928 extracted value might be an object or an array, use the
18929 <function>JSON_QUERY
</function> function instead.
18934 By default, the result, which must be a single scalar value, is
18935 returned as a value of type
<type>text
</type>, though the
18936 <literal>RETURNING
</literal> clause can be used to return as some
18937 other type to which it can be successfully coerced.
18942 The
<literal>ON ERROR
</literal> and
<literal>ON EMPTY
</literal>
18943 clauses have similar semantics as mentioned in the description of
18944 <function>JSON_QUERY
</function>, except the set of values returned in
18945 lieu of throwing an error is different.
18950 Note that scalar strings returned by
<function>JSON_VALUE
</function>
18951 always have their quotes removed, equivalent to specifying
18952 <literal>OMIT QUOTES
</literal> in
<function>JSON_QUERY
</function>.
18960 <literal>JSON_VALUE(jsonb '
"123.45"', '$' RETURNING float)
</literal>
18961 <returnvalue>123.45</returnvalue>
18964 <literal>JSON_VALUE(jsonb '
"03:04 2015-02-01"', '$.datetime(
"HH24:MI YYYY-MM-DD")' RETURNING date)
</literal>
18965 <returnvalue>2015-
02-
01</returnvalue>
18968 <literal>JSON_VALUE(jsonb '[
1,
2]', 'strict $[$off]' PASSING
1 as off)
</literal>
18969 <returnvalue>2</returnvalue>
18972 <literal>JSON_VALUE(jsonb '[
1,
2]', 'strict $[*]' DEFAULT
9 ON ERROR)
</literal>
18973 <returnvalue>9</returnvalue>
18982 The
<replaceable>context_item
</replaceable> expression is converted to
18983 <type>jsonb
</type> by an implicit cast if the expression is not already of
18984 type
<type>jsonb
</type>. Note, however, that any parsing errors that occur
18985 during that conversion are thrown unconditionally, that is, are not
18986 handled according to the (specified or implicit)
<literal>ON ERROR
</literal>
18992 <function>JSON_VALUE()
</function> returns an SQL NULL if
18993 <replaceable>path_expression
</replaceable> returns a JSON
18994 <literal>null
</literal>, whereas
<function>JSON_QUERY()
</function> returns
18995 the JSON
<literal>null
</literal> as is.
19000 <sect2 id=
"functions-sqljson-table">
19001 <title>JSON_TABLE
</title>
19003 <primary>json_table
</primary>
19007 <function>JSON_TABLE
</function> is an SQL/JSON function which
19008 queries
<acronym>JSON
</acronym> data
19009 and presents the results as a relational view, which can be accessed as a
19010 regular SQL table. You can use
<function>JSON_TABLE
</function> inside
19011 the
<literal>FROM
</literal> clause of a
<literal>SELECT
</literal>,
19012 <literal>UPDATE
</literal>, or
<literal>DELETE
</literal> and as data source
19013 in a
<literal>MERGE
</literal> statement.
19017 Taking JSON data as input,
<function>JSON_TABLE
</function> uses a JSON path
19018 expression to extract a part of the provided data to use as a
19019 <firstterm>row pattern
</firstterm> for the constructed view. Each SQL/JSON
19020 value given by the row pattern serves as source for a separate row in the
19025 To split the row pattern into columns,
<function>JSON_TABLE
</function>
19026 provides the
<literal>COLUMNS
</literal> clause that defines the
19027 schema of the created view. For each column, a separate JSON path expression
19028 can be specified to be evaluated against the row pattern to get an SQL/JSON
19029 value that will become the value for the specified column in a given output
19034 JSON data stored at a nested level of the row pattern can be extracted using
19035 the
<literal>NESTED PATH
</literal> clause. Each
19036 <literal>NESTED PATH
</literal> clause can be used to generate one or more
19037 columns using the data from a nested level of the row pattern. Those
19038 columns can be specified using a
<literal>COLUMNS
</literal> clause that
19039 looks similar to the top-level COLUMNS clause. Rows constructed from
19040 NESTED COLUMNS are called
<firstterm>child rows
</firstterm> and are joined
19041 against the row constructed from the columns specified in the parent
19042 <literal>COLUMNS
</literal> clause to get the row in the final view. Child
19043 columns themselves may contain a
<literal>NESTED PATH
</literal>
19044 specification thus allowing to extract data located at arbitrary nesting
19045 levels. Columns produced by multiple
<literal>NESTED PATH
</literal>s at the
19046 same level are considered to be
<firstterm>siblings
</firstterm> of each
19047 other and their rows after joining with the parent row are combined using
19052 The rows produced by
<function>JSON_TABLE
</function> are laterally
19053 joined to the row that generated them, so you do not have to explicitly join
19054 the constructed view with the original table holding
<acronym>JSON
</acronym>
19064 <replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable> <optional> AS
<replaceable>json_path_name
</replaceable> </optional> <optional> PASSING {
<replaceable>value
</replaceable> AS
<replaceable>varname
</replaceable> }
<optional>, ...
</optional> </optional>
19065 COLUMNS (
<replaceable class=
"parameter">json_table_column
</replaceable> <optional>, ...
</optional> )
19066 <optional> {
<literal>ERROR
</literal> |
<literal>EMPTY
</literal> <optional>ARRAY
</optional>}
<literal>ON ERROR
</literal> </optional>
19070 where
<replaceable class=
"parameter">json_table_column
</replaceable> is:
19072 <replaceable>name
</replaceable> FOR ORDINALITY
19073 |
<replaceable>name
</replaceable> <replaceable>type
</replaceable>
19074 <optional> FORMAT JSON
<optional>ENCODING
<literal>UTF8
</literal></optional></optional>
19075 <optional> PATH
<replaceable>path_expression
</replaceable> </optional>
19076 <optional> { WITHOUT | WITH { CONDITIONAL |
<optional>UNCONDITIONAL
</optional> } }
<optional> ARRAY
</optional> WRAPPER
</optional>
19077 <optional> { KEEP | OMIT } QUOTES
<optional> ON SCALAR STRING
</optional> </optional>
19078 <optional> { ERROR | NULL | EMPTY {
<optional>ARRAY
</optional> | OBJECT } | DEFAULT
<replaceable>expression
</replaceable> } ON EMPTY
</optional>
19079 <optional> { ERROR | NULL | EMPTY {
<optional>ARRAY
</optional> | OBJECT } | DEFAULT
<replaceable>expression
</replaceable> } ON ERROR
</optional>
19080 |
<replaceable>name
</replaceable> <replaceable>type
</replaceable> EXISTS
<optional> PATH
<replaceable>path_expression
</replaceable> </optional>
19081 <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR
</optional>
19082 | NESTED
<optional> PATH
</optional> <replaceable>path_expression
</replaceable> <optional> AS
<replaceable>json_path_name
</replaceable> </optional> COLUMNS (
<replaceable>json_table_column
</replaceable> <optional>, ...
</optional> )
19086 Each syntax element is described below in more detail.
19092 <literal><replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable> <optional> <literal>AS
</literal> <replaceable>json_path_name
</replaceable> </optional> <optional> <literal>PASSING
</literal> {
<replaceable>value
</replaceable> <literal>AS
</literal> <replaceable>varname
</replaceable> }
<optional>, ...
</optional></optional></literal>
19096 The
<replaceable>context_item
</replaceable> specifies the input document
19097 to query, the
<replaceable>path_expression
</replaceable> is an SQL/JSON
19098 path expression defining the query, and
<replaceable>json_path_name
</replaceable>
19099 is an optional name for the
<replaceable>path_expression
</replaceable>.
19100 The optional
<literal>PASSING
</literal> clause provides data values for
19101 the variables mentioned in the
<replaceable>path_expression
</replaceable>.
19102 The result of the input data evaluation using the aforementioned elements
19103 is called the
<firstterm>row pattern
</firstterm>, which is used as the
19104 source for row values in the constructed view.
19111 <literal>COLUMNS
</literal> (
<replaceable>json_table_column
</replaceable> <optional>, ...
</optional> )
19116 The
<literal>COLUMNS
</literal> clause defining the schema of the
19117 constructed view. In this clause, you can specify each column to be
19118 filled with an SQL/JSON value obtained by applying a JSON path expression
19119 against the row pattern.
<replaceable>json_table_column
</replaceable> has
19120 the following variants:
19126 <replaceable>name
</replaceable> <literal>FOR ORDINALITY
</literal>
19130 Adds an ordinality column that provides sequential row numbering starting
19131 from
1. Each
<literal>NESTED PATH
</literal> (see below) gets its own
19132 counter for any nested ordinality columns.
19139 <literal><replaceable>name
</replaceable> <replaceable>type
</replaceable>
19140 <optional><literal>FORMAT JSON
</literal> <optional>ENCODING
<literal>UTF8
</literal></optional></optional>
19141 <optional> <literal>PATH
</literal> <replaceable>path_expression
</replaceable> </optional></literal>
19145 Inserts an SQL/JSON value obtained by applying
19146 <replaceable>path_expression
</replaceable> against the row pattern into
19147 the view's output row after coercing it to specified
19148 <replaceable>type
</replaceable>.
19151 Specifying
<literal>FORMAT JSON
</literal> makes it explicit that you
19152 expect the value to be a valid
<type>json
</type> object. It only
19153 makes sense to specify
<literal>FORMAT JSON
</literal> if
19154 <replaceable>type
</replaceable> is one of
<type>bpchar
</type>,
19155 <type>bytea
</type>,
<type>character varying
</type>,
<type>name
</type>,
19156 <type>json
</type>,
<type>jsonb
</type>,
<type>text
</type>, or a domain over
19160 Optionally, you can specify
<literal>WRAPPER
</literal> and
19161 <literal>QUOTES
</literal> clauses to format the output. Note that
19162 specifying
<literal>OMIT QUOTES
</literal> overrides
19163 <literal>FORMAT JSON
</literal> if also specified, because unquoted
19164 literals do not constitute valid
<type>json
</type> values.
19167 Optionally, you can use
<literal>ON EMPTY
</literal> and
19168 <literal>ON ERROR
</literal> clauses to specify whether to throw the error
19169 or return the specified value when the result of JSON path evaluation is
19170 empty and when an error occurs during JSON path evaluation or when
19171 coercing the SQL/JSON value to the specified type, respectively. The
19172 default for both is to return a
<literal>NULL
</literal> value.
19176 This clause is internally turned into and has the same semantics as
19177 <function>JSON_VALUE
</function> or
<function>JSON_QUERY
</function>.
19178 The latter if the specified type is not a scalar type or if either of
19179 <literal>FORMAT JSON
</literal>,
<literal>WRAPPER
</literal>, or
19180 <literal>QUOTES
</literal> clause is present.
19188 <replaceable>name
</replaceable> <replaceable>type
</replaceable>
19189 <literal>EXISTS
</literal> <optional> <literal>PATH
</literal> <replaceable>path_expression
</replaceable> </optional>
19193 Inserts a boolean value obtained by applying
19194 <replaceable>path_expression
</replaceable> against the row pattern
19195 into the view's output row after coercing it to specified
19196 <replaceable>type
</replaceable>.
19199 The value corresponds to whether applying the
<literal>PATH
</literal>
19200 expression to the row pattern yields any values.
19203 The specified
<replaceable>type
</replaceable> should have a cast from the
19204 <type>boolean
</type> type.
19207 Optionally, you can use
<literal>ON ERROR
</literal> to specify whether to
19208 throw the error or return the specified value when an error occurs during
19209 JSON path evaluation or when coercing SQL/JSON value to the specified
19210 type. The default is to return a boolean value
19211 <literal>FALSE
</literal>.
19215 This clause is internally turned into and has the same semantics as
19216 <function>JSON_EXISTS
</function>.
19224 <literal>NESTED
<optional> PATH
</optional></literal> <replaceable>path_expression
</replaceable> <optional> <literal>AS
</literal> <replaceable>json_path_name
</replaceable> </optional>
19225 <literal>COLUMNS
</literal> (
<replaceable>json_table_column
</replaceable> <optional>, ...
</optional> )
19230 Extracts SQL/JSON values from nested levels of the row pattern,
19231 generates one or more columns as defined by the
<literal>COLUMNS
</literal>
19232 subclause, and inserts the extracted SQL/JSON values into those
19233 columns. The
<replaceable>json_table_column
</replaceable>
19234 expression in the
<literal>COLUMNS
</literal> subclause uses the same
19235 syntax as in the parent
<literal>COLUMNS
</literal> clause.
19239 The
<literal>NESTED PATH
</literal> syntax is recursive,
19240 so you can go down multiple nested levels by specifying several
19241 <literal>NESTED PATH
</literal> subclauses within each other.
19242 It allows to unnest the hierarchy of JSON objects and arrays
19243 in a single function invocation rather than chaining several
19244 <function>JSON_TABLE
</function> expressions in an SQL statement.
19252 In each variant of
<replaceable>json_table_column
</replaceable> described
19253 above, if the
<literal>PATH
</literal> clause is omitted, path expression
19254 <literal>$.
<replaceable>name
</replaceable></literal> is used, where
19255 <replaceable>name
</replaceable> is the provided column name.
19264 <literal>AS
</literal> <replaceable>json_path_name
</replaceable>
19269 The optional
<replaceable>json_path_name
</replaceable> serves as an
19270 identifier of the provided
<replaceable>path_expression
</replaceable>.
19271 The name must be unique and distinct from the column names.
19278 {
<literal>ERROR
</literal> |
<literal>EMPTY
</literal> }
<literal>ON ERROR
</literal>
19283 The optional
<literal>ON ERROR
</literal> can be used to specify how to
19284 handle errors when evaluating the top-level
19285 <replaceable>path_expression
</replaceable>. Use
<literal>ERROR
</literal>
19286 if you want the errors to be thrown and
<literal>EMPTY
</literal> to
19287 return an empty table, that is, a table containing
0 rows. Note that
19288 this clause does not affect the errors that occur when evaluating
19289 columns, for which the behavior depends on whether the
19290 <literal>ON ERROR
</literal> clause is specified against a given column.
19296 <para>Examples
</para>
19299 In the examples that follow, the following table containing JSON data
19303 CREATE TABLE my_films ( js jsonb );
19305 INSERT INTO my_films VALUES (
19307 {
"kind" :
"comedy",
"films" : [
19308 {
"title" :
"Bananas",
19309 "director" :
"Woody Allen"},
19310 {
"title" :
"The Dinner Game",
19311 "director" :
"Francis Veber" } ] },
19312 {
"kind" :
"horror",
"films" : [
19313 {
"title" :
"Psycho",
19314 "director" :
"Alfred Hitchcock" } ] },
19315 {
"kind" :
"thriller",
"films" : [
19316 {
"title" :
"Vertigo",
19317 "director" :
"Alfred Hitchcock" } ] },
19318 {
"kind" :
"drama",
"films" : [
19319 {
"title" :
"Yojimbo",
19320 "director" :
"Akira Kurosawa" } ] }
19326 The following query shows how to use
<function>JSON_TABLE
</function> to
19327 turn the JSON objects in the
<structname>my_films
</structname> table
19328 to a view containing columns for the keys
<literal>kind
</literal>,
19329 <literal>title
</literal>, and
<literal>director
</literal> contained in
19330 the original JSON along with an ordinality column:
19335 JSON_TABLE (js, '$.favorites[*]' COLUMNS (
19337 kind text PATH '$.kind',
19338 title text PATH '$.films[*].title' WITH WRAPPER,
19339 director text PATH '$.films[*].director' WITH WRAPPER)) AS jt;
19343 id | kind | title | director
19344 ----+----------+--------------------------------+----------------------------------
19345 1 | comedy | [
"Bananas",
"The Dinner Game"] | [
"Woody Allen",
"Francis Veber"]
19346 2 | horror | [
"Psycho"] | [
"Alfred Hitchcock"]
19347 3 | thriller | [
"Vertigo"] | [
"Alfred Hitchcock"]
19348 4 | drama | [
"Yojimbo"] | [
"Akira Kurosawa"]
19354 The following is a modified version of the above query to show the
19355 usage of
<literal>PASSING
</literal> arguments in the filter specified in
19356 the top-level JSON path expression and the various options for the
19357 individual columns:
19362 JSON_TABLE (js, '$.favorites[*] ? (@.films[*].director == $filter)'
19363 PASSING 'Alfred Hitchcock' AS filter, 'Vertigo' AS filter2
19366 kind text PATH '$.kind',
19367 title text FORMAT JSON PATH '$.films[*].title' OMIT QUOTES,
19368 director text PATH '$.films[*].director' KEEP QUOTES)) AS jt;
19372 id | kind | title | director
19373 ----+----------+---------+--------------------
19374 1 | horror | Psycho |
"Alfred Hitchcock"
19375 2 | thriller | Vertigo |
"Alfred Hitchcock"
19381 The following is a modified version of the above query to show the usage
19382 of
<literal>NESTED PATH
</literal> for populating title and director
19383 columns, illustrating how they are joined to the parent columns id and
19389 JSON_TABLE ( js, '$.favorites[*] ? (@.films[*].director == $filter)'
19390 PASSING 'Alfred Hitchcock' AS filter
19393 kind text PATH '$.kind',
19394 NESTED PATH '$.films[*]' COLUMNS (
19395 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
19396 director text PATH '$.director' KEEP QUOTES))) AS jt;
19400 id | kind | title | director
19401 ----+----------+---------+--------------------
19402 1 | horror | Psycho |
"Alfred Hitchcock"
19403 2 | thriller | Vertigo |
"Alfred Hitchcock"
19410 The following is the same query but without the filter in the root
19416 JSON_TABLE ( js, '$.favorites[*]'
19419 kind text PATH '$.kind',
19420 NESTED PATH '$.films[*]' COLUMNS (
19421 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
19422 director text PATH '$.director' KEEP QUOTES))) AS jt;
19426 id | kind | title | director
19427 ----+----------+-----------------+--------------------
19428 1 | comedy | Bananas |
"Woody Allen"
19429 1 | comedy | The Dinner Game |
"Francis Veber"
19430 2 | horror | Psycho |
"Alfred Hitchcock"
19431 3 | thriller | Vertigo |
"Alfred Hitchcock"
19432 4 | drama | Yojimbo |
"Akira Kurosawa"
19439 The following shows another query using a different
<type>JSON
</type>
19440 object as input. It shows the UNION
"sibling join" between
19441 <literal>NESTED
</literal> paths
<literal>$.movies[*]
</literal> and
19442 <literal>$.books[*]
</literal> and also the usage of
19443 <literal>FOR ORDINALITY
</literal> column at
<literal>NESTED
</literal>
19444 levels (columns
<literal>movie_id
</literal>,
<literal>book_id
</literal>,
19445 and
<literal>author_id
</literal>):
19448 SELECT * FROM JSON_TABLE (
19451 [{
"name":
"One",
"director":
"John Doe"},
19452 {
"name":
"Two",
"director":
"Don Joe"}],
19454 [{
"name":
"Mystery",
"authors": [{
"name":
"Brown Dan"}]},
19455 {
"name":
"Wonder",
"authors": [{
"name":
"Jun Murakami"}, {
"name":
"Craig Doe"}]}]
19456 }}'::json, '$.favorites[*]'
19458 user_id FOR ORDINALITY,
19459 NESTED '$.movies[*]'
19461 movie_id FOR ORDINALITY,
19462 mname text PATH '$.name',
19464 NESTED '$.books[*]'
19466 book_id FOR ORDINALITY,
19467 bname text PATH '$.name',
19468 NESTED '$.authors[*]'
19470 author_id FOR ORDINALITY,
19471 author_name text PATH '$.name'))));
19475 user_id | movie_id | mname | director | book_id | bname | author_id | author_name
19476 ---------+----------+-------+----------+---------+---------+-----------+--------------
19477 1 |
1 | One | John Doe | | | |
19478 1 |
2 | Two | Don Joe | | | |
19479 1 | | | |
1 | Mystery |
1 | Brown Dan
19480 1 | | | |
2 | Wonder |
1 | Jun Murakami
19481 1 | | | |
2 | Wonder |
2 | Craig Doe
19489 <sect1 id=
"functions-sequence">
19490 <title>Sequence Manipulation Functions
</title>
19493 <primary>sequence
</primary>
19497 This section describes functions for operating on
<firstterm>sequence
19498 objects
</firstterm>, also called sequence generators or just sequences.
19499 Sequence objects are special single-row tables created with
<xref
19500 linkend=
"sql-createsequence"/>.
19501 Sequence objects are commonly used to generate unique identifiers
19502 for rows of a table. The sequence functions, listed in
<xref
19503 linkend=
"functions-sequence-table"/>, provide simple, multiuser-safe
19504 methods for obtaining successive sequence values from sequence
19508 <table id=
"functions-sequence-table">
19509 <title>Sequence Functions
</title>
19513 <entry role=
"func_table_entry"><para role=
"func_signature">
19524 <entry role=
"func_table_entry"><para role=
"func_signature">
19526 <primary>nextval
</primary>
19528 <function>nextval
</function> (
<type>regclass
</type> )
19529 <returnvalue>bigint
</returnvalue>
19532 Advances the sequence object to its next value and returns that value.
19533 This is done atomically: even if multiple sessions
19534 execute
<function>nextval
</function> concurrently, each will safely
19535 receive a distinct sequence value.
19536 If the sequence object has been created with default parameters,
19537 successive
<function>nextval
</function> calls will return successive
19538 values beginning with
1. Other behaviors can be obtained by using
19539 appropriate parameters in the
<xref linkend=
"sql-createsequence"/>
19543 This function requires
<literal>USAGE
</literal>
19544 or
<literal>UPDATE
</literal> privilege on the sequence.
19549 <entry role=
"func_table_entry"><para role=
"func_signature">
19551 <primary>setval
</primary>
19553 <function>setval
</function> (
<type>regclass
</type>,
<type>bigint
</type> <optional>,
<type>boolean
</type> </optional> )
19554 <returnvalue>bigint
</returnvalue>
19557 Sets the sequence object's current value, and optionally
19558 its
<literal>is_called
</literal> flag. The two-parameter
19559 form sets the sequence's
<literal>last_value
</literal> field to the
19560 specified value and sets its
<literal>is_called
</literal> field to
19561 <literal>true
</literal>, meaning that the next
19562 <function>nextval
</function> will advance the sequence before
19563 returning a value. The value that will be reported
19564 by
<function>currval
</function> is also set to the specified value.
19565 In the three-parameter form,
<literal>is_called
</literal> can be set
19566 to either
<literal>true
</literal>
19567 or
<literal>false
</literal>.
<literal>true
</literal> has the same
19568 effect as the two-parameter form. If it is set
19569 to
<literal>false
</literal>, the next
<function>nextval
</function>
19570 will return exactly the specified value, and sequence advancement
19571 commences with the following
<function>nextval
</function>.
19572 Furthermore, the value reported by
<function>currval
</function> is not
19573 changed in this case. For example,
19575 SELECT setval('myseq',
42);
<lineannotation>Next
<function>nextval
</function> will return
43</lineannotation>
19576 SELECT setval('myseq',
42, true);
<lineannotation>Same as above
</lineannotation>
19577 SELECT setval('myseq',
42, false);
<lineannotation>Next
<function>nextval
</function> will return
42</lineannotation>
19579 The result returned by
<function>setval
</function> is just the value of its
19583 This function requires
<literal>UPDATE
</literal> privilege on the
19589 <entry role=
"func_table_entry"><para role=
"func_signature">
19591 <primary>currval
</primary>
19593 <function>currval
</function> (
<type>regclass
</type> )
19594 <returnvalue>bigint
</returnvalue>
19597 Returns the value most recently obtained
19598 by
<function>nextval
</function> for this sequence in the current
19599 session. (An error is reported if
<function>nextval
</function> has
19600 never been called for this sequence in this session.) Because this is
19601 returning a session-local value, it gives a predictable answer whether
19602 or not other sessions have executed
<function>nextval
</function> since
19603 the current session did.
19606 This function requires
<literal>USAGE
</literal>
19607 or
<literal>SELECT
</literal> privilege on the sequence.
19612 <entry role=
"func_table_entry"><para role=
"func_signature">
19614 <primary>lastval
</primary>
19616 <function>lastval
</function> ()
19617 <returnvalue>bigint
</returnvalue>
19620 Returns the value most recently returned by
19621 <function>nextval
</function> in the current session. This function is
19622 identical to
<function>currval
</function>, except that instead
19623 of taking the sequence name as an argument it refers to whichever
19624 sequence
<function>nextval
</function> was most recently applied to
19625 in the current session. It is an error to call
19626 <function>lastval
</function> if
<function>nextval
</function>
19627 has not yet been called in the current session.
19630 This function requires
<literal>USAGE
</literal>
19631 or
<literal>SELECT
</literal> privilege on the last used sequence.
19640 To avoid blocking concurrent transactions that obtain numbers from
19641 the same sequence, the value obtained by
<function>nextval
</function>
19642 is not reclaimed for re-use if the calling transaction later aborts.
19643 This means that transaction aborts or database crashes can result in
19644 gaps in the sequence of assigned values. That can happen without a
19645 transaction abort, too. For example an
<command>INSERT
</command> with
19646 an
<literal>ON CONFLICT
</literal> clause will compute the to-be-inserted
19647 tuple, including doing any required
<function>nextval
</function>
19648 calls, before detecting any conflict that would cause it to follow
19649 the
<literal>ON CONFLICT
</literal> rule instead.
19650 Thus,
<productname>PostgreSQL
</productname> sequence
19651 objects
<emphasis>cannot be used to obtain
<quote>gapless
</quote>
19652 sequences
</emphasis>.
19656 Likewise, sequence state changes made by
<function>setval
</function>
19657 are immediately visible to other transactions, and are not undone if
19658 the calling transaction rolls back.
19662 If the database cluster crashes before committing a transaction
19663 containing a
<function>nextval
</function>
19664 or
<function>setval
</function> call, the sequence state change might
19665 not have made its way to persistent storage, so that it is uncertain
19666 whether the sequence will have its original or updated state after the
19667 cluster restarts. This is harmless for usage of the sequence within
19668 the database, since other effects of uncommitted transactions will not
19669 be visible either. However, if you wish to use a sequence value for
19670 persistent outside-the-database purposes, make sure that the
19671 <function>nextval
</function> call has been committed before doing so.
19676 The sequence to be operated on by a sequence function is specified by
19677 a
<type>regclass
</type> argument, which is simply the OID of the sequence in the
19678 <structname>pg_class
</structname> system catalog. You do not have to look up the
19679 OID by hand, however, since the
<type>regclass
</type> data type's input
19680 converter will do the work for you. See
<xref linkend=
"datatype-oid"/>
19686 <sect1 id=
"functions-conditional">
19687 <title>Conditional Expressions
</title>
19690 <primary>CASE
</primary>
19694 <primary>conditional expression
</primary>
19698 This section describes the
<acronym>SQL
</acronym>-compliant conditional expressions
19699 available in
<productname>PostgreSQL
</productname>.
19704 If your needs go beyond the capabilities of these conditional
19705 expressions, you might want to consider writing a server-side function
19706 in a more expressive programming language.
19712 Although
<token>COALESCE
</token>,
<token>GREATEST
</token>, and
19713 <token>LEAST
</token> are syntactically similar to functions, they are
19714 not ordinary functions, and thus cannot be used with explicit
19715 <token>VARIADIC
</token> array arguments.
19719 <sect2 id=
"functions-case">
19720 <title><literal>CASE
</literal></title>
19723 The
<acronym>SQL
</acronym> <token>CASE
</token> expression is a
19724 generic conditional expression, similar to if/else statements in
19725 other programming languages:
19728 CASE WHEN
<replaceable>condition
</replaceable> THEN
<replaceable>result
</replaceable>
19729 <optional>WHEN ...
</optional>
19730 <optional>ELSE
<replaceable>result
</replaceable></optional>
19734 <token>CASE
</token> clauses can be used wherever
19735 an expression is valid. Each
<replaceable>condition
</replaceable> is an
19736 expression that returns a
<type>boolean
</type> result. If the condition's
19737 result is true, the value of the
<token>CASE
</token> expression is the
19738 <replaceable>result
</replaceable> that follows the condition, and the
19739 remainder of the
<token>CASE
</token> expression is not processed. If the
19740 condition's result is not true, any subsequent
<token>WHEN
</token> clauses
19741 are examined in the same manner. If no
<token>WHEN
</token>
19742 <replaceable>condition
</replaceable> yields true, the value of the
19743 <token>CASE
</token> expression is the
<replaceable>result
</replaceable> of the
19744 <token>ELSE
</token> clause. If the
<token>ELSE
</token> clause is
19745 omitted and no condition is true, the result is null.
19751 SELECT * FROM test;
19761 CASE WHEN a=
1 THEN 'one'
19762 WHEN a=
2 THEN 'two'
19776 The data types of all the
<replaceable>result
</replaceable>
19777 expressions must be convertible to a single output type.
19778 See
<xref linkend=
"typeconv-union-case"/> for more details.
19782 There is a
<quote>simple
</quote> form of
<token>CASE
</token> expression
19783 that is a variant of the general form above:
19786 CASE
<replaceable>expression
</replaceable>
19787 WHEN
<replaceable>value
</replaceable> THEN
<replaceable>result
</replaceable>
19788 <optional>WHEN ...
</optional>
19789 <optional>ELSE
<replaceable>result
</replaceable></optional>
19794 <replaceable>expression
</replaceable> is computed, then compared to
19795 each of the
<replaceable>value
</replaceable> expressions in the
19796 <token>WHEN
</token> clauses until one is found that is equal to it. If
19797 no match is found, the
<replaceable>result
</replaceable> of the
19798 <token>ELSE
</token> clause (or a null value) is returned. This is similar
19799 to the
<function>switch
</function> statement in C.
19803 The example above can be written using the simple
19804 <token>CASE
</token> syntax:
19807 CASE a WHEN
1 THEN 'one'
19822 A
<token>CASE
</token> expression does not evaluate any subexpressions
19823 that are not needed to determine the result. For example, this is a
19824 possible way of avoiding a division-by-zero failure:
19826 SELECT ... WHERE CASE WHEN x
<> 0 THEN y/x
> 1.5 ELSE false END;
19832 As described in
<xref linkend=
"syntax-express-eval"/>, there are various
19833 situations in which subexpressions of an expression are evaluated at
19834 different times, so that the principle that
<quote><token>CASE
</token>
19835 evaluates only necessary subexpressions
</quote> is not ironclad. For
19836 example a constant
<literal>1/
0</literal> subexpression will usually result in
19837 a division-by-zero failure at planning time, even if it's within
19838 a
<token>CASE
</token> arm that would never be entered at run time.
19843 <sect2 id=
"functions-coalesce-nvl-ifnull">
19844 <title><literal>COALESCE
</literal></title>
19847 <primary>COALESCE
</primary>
19851 <primary>NVL
</primary>
19855 <primary>IFNULL
</primary>
19859 <function>COALESCE
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
19863 The
<function>COALESCE
</function> function returns the first of its
19864 arguments that is not null. Null is returned only if all arguments
19865 are null. It is often used to substitute a default value for
19866 null values when data is retrieved for display, for example:
19868 SELECT COALESCE(description, short_description, '(none)') ...
19870 This returns
<varname>description
</varname> if it is not null, otherwise
19871 <varname>short_description
</varname> if it is not null, otherwise
<literal>(none)
</literal>.
19875 The arguments must all be convertible to a common data type, which
19876 will be the type of the result (see
19877 <xref linkend=
"typeconv-union-case"/> for details).
19881 Like a
<token>CASE
</token> expression,
<function>COALESCE
</function> only
19882 evaluates the arguments that are needed to determine the result;
19883 that is, arguments to the right of the first non-null argument are
19884 not evaluated. This SQL-standard function provides capabilities similar
19885 to
<function>NVL
</function> and
<function>IFNULL
</function>, which are used in some other
19890 <sect2 id=
"functions-nullif">
19891 <title><literal>NULLIF
</literal></title>
19894 <primary>NULLIF
</primary>
19898 <function>NULLIF
</function>(
<replaceable>value1
</replaceable>,
<replaceable>value2
</replaceable>)
19902 The
<function>NULLIF
</function> function returns a null value if
19903 <replaceable>value1
</replaceable> equals
<replaceable>value2
</replaceable>;
19904 otherwise it returns
<replaceable>value1
</replaceable>.
19905 This can be used to perform the inverse operation of the
19906 <function>COALESCE
</function> example given above:
19908 SELECT NULLIF(value, '(none)') ...
19910 In this example, if
<literal>value
</literal> is
<literal>(none)
</literal>,
19911 null is returned, otherwise the value of
<literal>value
</literal>
19916 The two arguments must be of comparable types.
19917 To be specific, they are compared exactly as if you had
19918 written
<literal><replaceable>value1
</replaceable>
19919 =
<replaceable>value2
</replaceable></literal>, so there must be a
19920 suitable
<literal>=
</literal> operator available.
19924 The result has the same type as the first argument
— but there is
19925 a subtlety. What is actually returned is the first argument of the
19926 implied
<literal>=
</literal> operator, and in some cases that will have
19927 been promoted to match the second argument's type. For
19928 example,
<literal>NULLIF(
1,
2.2)
</literal> yields
<type>numeric
</type>,
19929 because there is no
<type>integer
</type> <literal>=
</literal>
19930 <type>numeric
</type> operator,
19931 only
<type>numeric
</type> <literal>=
</literal> <type>numeric
</type>.
19936 <sect2 id=
"functions-greatest-least">
19937 <title><literal>GREATEST
</literal> and
<literal>LEAST
</literal></title>
19940 <primary>GREATEST
</primary>
19943 <primary>LEAST
</primary>
19947 <function>GREATEST
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
19950 <function>LEAST
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
19954 The
<function>GREATEST
</function> and
<function>LEAST
</function> functions select the
19955 largest or smallest value from a list of any number of expressions.
19956 The expressions must all be convertible to a common data type, which
19957 will be the type of the result
19958 (see
<xref linkend=
"typeconv-union-case"/> for details).
19962 NULL values in the argument list are ignored. The result will be NULL
19963 only if all the expressions evaluate to NULL. (This is a deviation from
19964 the SQL standard. According to the standard, the return value is NULL if
19965 any argument is NULL. Some other databases behave this way.)
19970 <sect1 id=
"functions-array">
19971 <title>Array Functions and Operators
</title>
19974 <xref linkend=
"array-operators-table"/> shows the specialized operators
19975 available for array types.
19976 In addition to those, the usual comparison operators shown in
<xref
19977 linkend=
"functions-comparison-op-table"/> are available for
19978 arrays. The comparison operators compare the array contents
19979 element-by-element, using the default B-tree comparison function for
19980 the element data type, and sort based on the first difference.
19981 In multidimensional arrays the elements are visited in row-major order
19982 (last subscript varies most rapidly).
19983 If the contents of two arrays are equal but the dimensionality is
19984 different, the first difference in the dimensionality information
19985 determines the sort order.
19988 <table id=
"array-operators-table">
19989 <title>Array Operators
</title>
19993 <entry role=
"func_table_entry"><para role=
"func_signature">
20007 <entry role=
"func_table_entry"><para role=
"func_signature">
20008 <type>anyarray
</type> <literal>@
></literal> <type>anyarray
</type>
20009 <returnvalue>boolean
</returnvalue>
20012 Does the first array contain the second, that is, does each element
20013 appearing in the second array equal some element of the first array?
20014 (Duplicates are not treated specially,
20015 thus
<literal>ARRAY[
1]
</literal> and
<literal>ARRAY[
1,
1]
</literal> are
20016 each considered to contain the other.)
20019 <literal>ARRAY[
1,
4,
3] @
> ARRAY[
3,
1,
3]
</literal>
20020 <returnvalue>t
</returnvalue>
20025 <entry role=
"func_table_entry"><para role=
"func_signature">
20026 <type>anyarray
</type> <literal><@
</literal> <type>anyarray
</type>
20027 <returnvalue>boolean
</returnvalue>
20030 Is the first array contained by the second?
20033 <literal>ARRAY[
2,
2,
7]
<@ ARRAY[
1,
7,
4,
2,
6]
</literal>
20034 <returnvalue>t
</returnvalue>
20039 <entry role=
"func_table_entry"><para role=
"func_signature">
20040 <type>anyarray
</type> <literal>&&</literal> <type>anyarray
</type>
20041 <returnvalue>boolean
</returnvalue>
20044 Do the arrays overlap, that is, have any elements in common?
20047 <literal>ARRAY[
1,
4,
3]
&& ARRAY[
2,
1]
</literal>
20048 <returnvalue>t
</returnvalue>
20053 <entry role=
"func_table_entry"><para role=
"func_signature">
20054 <type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20055 <returnvalue>anycompatiblearray
</returnvalue>
20058 Concatenates the two arrays. Concatenating a null or empty array is a
20059 no-op; otherwise the arrays must have the same number of dimensions
20060 (as illustrated by the first example) or differ in number of
20061 dimensions by one (as illustrated by the second).
20062 If the arrays are not of identical element types, they will be coerced
20063 to a common type (see
<xref linkend=
"typeconv-union-case"/>).
20066 <literal>ARRAY[
1,
2,
3] || ARRAY[
4,
5,
6,
7]
</literal>
20067 <returnvalue>{
1,
2,
3,
4,
5,
6,
7}
</returnvalue>
20070 <literal>ARRAY[
1,
2,
3] || ARRAY[[
4,
5,
6],[
7,
8,
9.9]]
</literal>
20071 <returnvalue>{{
1,
2,
3},{
4,
5,
6},{
7,
8,
9.9}}
</returnvalue>
20076 <entry role=
"func_table_entry"><para role=
"func_signature">
20077 <type>anycompatible
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20078 <returnvalue>anycompatiblearray
</returnvalue>
20081 Concatenates an element onto the front of an array (which must be
20082 empty or one-dimensional).
20085 <literal>3 || ARRAY[
4,
5,
6]
</literal>
20086 <returnvalue>{
3,
4,
5,
6}
</returnvalue>
20091 <entry role=
"func_table_entry"><para role=
"func_signature">
20092 <type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatible
</type>
20093 <returnvalue>anycompatiblearray
</returnvalue>
20096 Concatenates an element onto the end of an array (which must be
20097 empty or one-dimensional).
20100 <literal>ARRAY[
4,
5,
6] ||
7</literal>
20101 <returnvalue>{
4,
5,
6,
7}
</returnvalue>
20109 See
<xref linkend=
"arrays"/> for more details about array operator
20110 behavior. See
<xref linkend=
"indexes-types"/> for more details about
20111 which operators support indexed operations.
20115 <xref linkend=
"array-functions-table"/> shows the functions
20116 available for use with array types. See
<xref linkend=
"arrays"/>
20117 for more information and examples of the use of these functions.
20120 <table id=
"array-functions-table">
20121 <title>Array Functions
</title>
20125 <entry role=
"func_table_entry"><para role=
"func_signature">
20139 <entry role=
"func_table_entry"><para role=
"func_signature">
20141 <primary>array_append
</primary>
20143 <function>array_append
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
20144 <returnvalue>anycompatiblearray
</returnvalue>
20147 Appends an element to the end of an array (same as
20148 the
<type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatible
</type>
20152 <literal>array_append(ARRAY[
1,
2],
3)
</literal>
20153 <returnvalue>{
1,
2,
3}
</returnvalue>
20158 <entry role=
"func_table_entry"><para role=
"func_signature">
20160 <primary>array_cat
</primary>
20162 <function>array_cat
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatiblearray
</type> )
20163 <returnvalue>anycompatiblearray
</returnvalue>
20166 Concatenates two arrays (same as
20167 the
<type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20171 <literal>array_cat(ARRAY[
1,
2,
3], ARRAY[
4,
5])
</literal>
20172 <returnvalue>{
1,
2,
3,
4,
5}
</returnvalue>
20177 <entry role=
"func_table_entry"><para role=
"func_signature">
20179 <primary>array_dims
</primary>
20181 <function>array_dims
</function> (
<type>anyarray
</type> )
20182 <returnvalue>text
</returnvalue>
20185 Returns a text representation of the array's dimensions.
20188 <literal>array_dims(ARRAY[[
1,
2,
3], [
4,
5,
6]])
</literal>
20189 <returnvalue>[
1:
2][
1:
3]
</returnvalue>
20194 <entry role=
"func_table_entry"><para role=
"func_signature">
20196 <primary>array_fill
</primary>
20198 <function>array_fill
</function> (
<type>anyelement
</type>,
<type>integer[]
</type>
20199 <optional>,
<type>integer[]
</type> </optional> )
20200 <returnvalue>anyarray
</returnvalue>
20203 Returns an array filled with copies of the given value, having
20204 dimensions of the lengths specified by the second argument.
20205 The optional third argument supplies lower-bound values for each
20206 dimension (which default to all
<literal>1</literal>).
20209 <literal>array_fill(
11, ARRAY[
2,
3])
</literal>
20210 <returnvalue>{{
11,
11,
11},{
11,
11,
11}}
</returnvalue>
20213 <literal>array_fill(
7, ARRAY[
3], ARRAY[
2])
</literal>
20214 <returnvalue>[
2:
4]={
7,
7,
7}
</returnvalue>
20219 <entry role=
"func_table_entry"><para role=
"func_signature">
20221 <primary>array_length
</primary>
20223 <function>array_length
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
20224 <returnvalue>integer
</returnvalue>
20227 Returns the length of the requested array dimension.
20228 (Produces NULL instead of
0 for empty or missing array dimensions.)
20231 <literal>array_length(array[
1,
2,
3],
1)
</literal>
20232 <returnvalue>3</returnvalue>
20235 <literal>array_length(array[]::int[],
1)
</literal>
20236 <returnvalue>NULL
</returnvalue>
20239 <literal>array_length(array['text'],
2)
</literal>
20240 <returnvalue>NULL
</returnvalue>
20245 <entry role=
"func_table_entry"><para role=
"func_signature">
20247 <primary>array_lower
</primary>
20249 <function>array_lower
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
20250 <returnvalue>integer
</returnvalue>
20253 Returns the lower bound of the requested array dimension.
20256 <literal>array_lower('[
0:
2]={
1,
2,
3}'::integer[],
1)
</literal>
20257 <returnvalue>0</returnvalue>
20262 <entry role=
"func_table_entry"><para role=
"func_signature">
20264 <primary>array_ndims
</primary>
20266 <function>array_ndims
</function> (
<type>anyarray
</type> )
20267 <returnvalue>integer
</returnvalue>
20270 Returns the number of dimensions of the array.
20273 <literal>array_ndims(ARRAY[[
1,
2,
3], [
4,
5,
6]])
</literal>
20274 <returnvalue>2</returnvalue>
20279 <entry role=
"func_table_entry"><para role=
"func_signature">
20281 <primary>array_position
</primary>
20283 <function>array_position
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> <optional>,
<type>integer
</type> </optional> )
20284 <returnvalue>integer
</returnvalue>
20287 Returns the subscript of the first occurrence of the second argument
20288 in the array, or
<literal>NULL
</literal> if it's not present.
20289 If the third argument is given, the search begins at that subscript.
20290 The array must be one-dimensional.
20291 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
20292 semantics, so it is possible to search for
<literal>NULL
</literal>.
20295 <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')
</literal>
20296 <returnvalue>2</returnvalue>
20301 <entry role=
"func_table_entry"><para role=
"func_signature">
20303 <primary>array_positions
</primary>
20305 <function>array_positions
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
20306 <returnvalue>integer[]
</returnvalue>
20309 Returns an array of the subscripts of all occurrences of the second
20310 argument in the array given as first argument.
20311 The array must be one-dimensional.
20312 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
20313 semantics, so it is possible to search for
<literal>NULL
</literal>.
20314 <literal>NULL
</literal> is returned only if the array
20315 is
<literal>NULL
</literal>; if the value is not found in the array, an
20316 empty array is returned.
20319 <literal>array_positions(ARRAY['A','A','B','A'], 'A')
</literal>
20320 <returnvalue>{
1,
2,
4}
</returnvalue>
20325 <entry role=
"func_table_entry"><para role=
"func_signature">
20327 <primary>array_prepend
</primary>
20329 <function>array_prepend
</function> (
<type>anycompatible
</type>,
<type>anycompatiblearray
</type> )
20330 <returnvalue>anycompatiblearray
</returnvalue>
20333 Prepends an element to the beginning of an array (same as
20334 the
<type>anycompatible
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20338 <literal>array_prepend(
1, ARRAY[
2,
3])
</literal>
20339 <returnvalue>{
1,
2,
3}
</returnvalue>
20344 <entry role=
"func_table_entry"><para role=
"func_signature">
20346 <primary>array_remove
</primary>
20348 <function>array_remove
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
20349 <returnvalue>anycompatiblearray
</returnvalue>
20352 Removes all elements equal to the given value from the array.
20353 The array must be one-dimensional.
20354 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
20355 semantics, so it is possible to remove
<literal>NULL
</literal>s.
20358 <literal>array_remove(ARRAY[
1,
2,
3,
2],
2)
</literal>
20359 <returnvalue>{
1,
3}
</returnvalue>
20364 <entry role=
"func_table_entry"><para role=
"func_signature">
20366 <primary>array_replace
</primary>
20368 <function>array_replace
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type>,
<type>anycompatible
</type> )
20369 <returnvalue>anycompatiblearray
</returnvalue>
20372 Replaces each array element equal to the second argument with the
20376 <literal>array_replace(ARRAY[
1,
2,
5,
4],
5,
3)
</literal>
20377 <returnvalue>{
1,
2,
3,
4}
</returnvalue>
20382 <entry role=
"func_table_entry"><para role=
"func_signature">
20384 <primary>array_sample
</primary>
20386 <function>array_sample
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>n
</parameter> <type>integer
</type> )
20387 <returnvalue>anyarray
</returnvalue>
20390 Returns an array of
<parameter>n
</parameter> items randomly selected
20391 from
<parameter>array
</parameter>.
<parameter>n
</parameter> may not
20392 exceed the length of
<parameter>array
</parameter>'s first dimension.
20393 If
<parameter>array
</parameter> is multi-dimensional,
20394 an
<quote>item
</quote> is a slice having a given first subscript.
20397 <literal>array_sample(ARRAY[
1,
2,
3,
4,
5,
6],
3)
</literal>
20398 <returnvalue>{
2,
6,
1}
</returnvalue>
20401 <literal>array_sample(ARRAY[[
1,
2],[
3,
4],[
5,
6]],
2)
</literal>
20402 <returnvalue>{{
5,
6},{
1,
2}}
</returnvalue>
20407 <entry role=
"func_table_entry"><para role=
"func_signature">
20409 <primary>array_shuffle
</primary>
20411 <function>array_shuffle
</function> (
<type>anyarray
</type> )
20412 <returnvalue>anyarray
</returnvalue>
20415 Randomly shuffles the first dimension of the array.
20418 <literal>array_shuffle(ARRAY[[
1,
2],[
3,
4],[
5,
6]])
</literal>
20419 <returnvalue>{{
5,
6},{
1,
2},{
3,
4}}
</returnvalue>
20424 <entry role=
"func_table_entry"><para role=
"func_signature">
20425 <indexterm id=
"function-array-to-string">
20426 <primary>array_to_string
</primary>
20428 <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> )
20429 <returnvalue>text
</returnvalue>
20432 Converts each array element to its text representation, and
20433 concatenates those separated by
20434 the
<parameter>delimiter
</parameter> string.
20435 If
<parameter>null_string
</parameter> is given and is
20436 not
<literal>NULL
</literal>, then
<literal>NULL
</literal> array
20437 entries are represented by that string; otherwise, they are omitted.
20438 See also
<link linkend=
"function-string-to-array"><function>string_to_array
</function></link>.
20441 <literal>array_to_string(ARRAY[
1,
2,
3, NULL,
5], ',', '*')
</literal>
20442 <returnvalue>1,
2,
3,*,
5</returnvalue>
20447 <entry role=
"func_table_entry"><para role=
"func_signature">
20449 <primary>array_upper
</primary>
20451 <function>array_upper
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
20452 <returnvalue>integer
</returnvalue>
20455 Returns the upper bound of the requested array dimension.
20458 <literal>array_upper(ARRAY[
1,
8,
3,
7],
1)
</literal>
20459 <returnvalue>4</returnvalue>
20464 <entry role=
"func_table_entry"><para role=
"func_signature">
20466 <primary>cardinality
</primary>
20468 <function>cardinality
</function> (
<type>anyarray
</type> )
20469 <returnvalue>integer
</returnvalue>
20472 Returns the total number of elements in the array, or
0 if the array
20476 <literal>cardinality(ARRAY[[
1,
2],[
3,
4]])
</literal>
20477 <returnvalue>4</returnvalue>
20482 <entry role=
"func_table_entry"><para role=
"func_signature">
20484 <primary>trim_array
</primary>
20486 <function>trim_array
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>n
</parameter> <type>integer
</type> )
20487 <returnvalue>anyarray
</returnvalue>
20490 Trims an array by removing the last
<parameter>n
</parameter> elements.
20491 If the array is multidimensional, only the first dimension is trimmed.
20494 <literal>trim_array(ARRAY[
1,
2,
3,
4,
5,
6],
2)
</literal>
20495 <returnvalue>{
1,
2,
3,
4}
</returnvalue>
20500 <entry role=
"func_table_entry"><para role=
"func_signature">
20502 <primary>unnest
</primary>
20504 <function>unnest
</function> (
<type>anyarray
</type> )
20505 <returnvalue>setof anyelement
</returnvalue>
20508 Expands an array into a set of rows.
20509 The array's elements are read out in storage order.
20512 <literal>unnest(ARRAY[
1,
2])
</literal>
20513 <returnvalue></returnvalue>
20520 <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])
</literal>
20521 <returnvalue></returnvalue>
20532 <entry role=
"func_table_entry"><para role=
"func_signature">
20533 <function>unnest
</function> (
<type>anyarray
</type>,
<type>anyarray
</type> <optional>, ...
</optional> )
20534 <returnvalue>setof anyelement, anyelement [, ... ]
</returnvalue>
20537 Expands multiple arrays (possibly of different data types) into a set of
20538 rows. If the arrays are not all the same length then the shorter ones
20539 are padded with
<literal>NULL
</literal>s. This form is only allowed
20540 in a query's FROM clause; see
<xref linkend=
"queries-tablefunctions"/>.
20543 <literal>select * from unnest(ARRAY[
1,
2], ARRAY['foo','bar','baz']) as x(a,b)
</literal>
20544 <returnvalue></returnvalue>
20559 See also
<xref linkend=
"functions-aggregate"/> about the aggregate
20560 function
<function>array_agg
</function> for use with arrays.
20564 <sect1 id=
"functions-range">
20565 <title>Range/Multirange Functions and Operators
</title>
20568 See
<xref linkend=
"rangetypes"/> for an overview of range types.
20572 <xref linkend=
"range-operators-table"/> shows the specialized operators
20573 available for range types.
20574 <xref linkend=
"multirange-operators-table"/> shows the specialized operators
20575 available for multirange types.
20576 In addition to those, the usual comparison operators shown in
20577 <xref linkend=
"functions-comparison-op-table"/> are available for range
20578 and multirange types. The comparison operators order first by the range lower
20579 bounds, and only if those are equal do they compare the upper bounds. The
20580 multirange operators compare each range until one is unequal. This
20581 does not usually result in a useful overall ordering, but the operators are
20582 provided to allow unique indexes to be constructed on ranges.
20585 <table id=
"range-operators-table">
20586 <title>Range Operators
</title>
20590 <entry role=
"func_table_entry"><para role=
"func_signature">
20604 <entry role=
"func_table_entry"><para role=
"func_signature">
20605 <type>anyrange
</type> <literal>@
></literal> <type>anyrange
</type>
20606 <returnvalue>boolean
</returnvalue>
20609 Does the first range contain the second?
20612 <literal>int4range(
2,
4) @
> int4range(
2,
3)
</literal>
20613 <returnvalue>t
</returnvalue>
20618 <entry role=
"func_table_entry"><para role=
"func_signature">
20619 <type>anyrange
</type> <literal>@
></literal> <type>anyelement
</type>
20620 <returnvalue>boolean
</returnvalue>
20623 Does the range contain the element?
20626 <literal>'[
2011-
01-
01,
2011-
03-
01)'::tsrange @
> '
2011-
01-
10'::timestamp
</literal>
20627 <returnvalue>t
</returnvalue>
20632 <entry role=
"func_table_entry"><para role=
"func_signature">
20633 <type>anyrange
</type> <literal><@
</literal> <type>anyrange
</type>
20634 <returnvalue>boolean
</returnvalue>
20637 Is the first range contained by the second?
20640 <literal>int4range(
2,
4)
<@ int4range(
1,
7)
</literal>
20641 <returnvalue>t
</returnvalue>
20646 <entry role=
"func_table_entry"><para role=
"func_signature">
20647 <type>anyelement
</type> <literal><@
</literal> <type>anyrange
</type>
20648 <returnvalue>boolean
</returnvalue>
20651 Is the element contained in the range?
20654 <literal>42 <@ int4range(
1,
7)
</literal>
20655 <returnvalue>f
</returnvalue>
20660 <entry role=
"func_table_entry"><para role=
"func_signature">
20661 <type>anyrange
</type> <literal>&&</literal> <type>anyrange
</type>
20662 <returnvalue>boolean
</returnvalue>
20665 Do the ranges overlap, that is, have any elements in common?
20668 <literal>int8range(
3,
7)
&& int8range(
4,
12)
</literal>
20669 <returnvalue>t
</returnvalue>
20674 <entry role=
"func_table_entry"><para role=
"func_signature">
20675 <type>anyrange
</type> <literal><<</literal> <type>anyrange
</type>
20676 <returnvalue>boolean
</returnvalue>
20679 Is the first range strictly left of the second?
20682 <literal>int8range(
1,
10)
<< int8range(
100,
110)
</literal>
20683 <returnvalue>t
</returnvalue>
20688 <entry role=
"func_table_entry"><para role=
"func_signature">
20689 <type>anyrange
</type> <literal>>></literal> <type>anyrange
</type>
20690 <returnvalue>boolean
</returnvalue>
20693 Is the first range strictly right of the second?
20696 <literal>int8range(
50,
60)
>> int8range(
20,
30)
</literal>
20697 <returnvalue>t
</returnvalue>
20702 <entry role=
"func_table_entry"><para role=
"func_signature">
20703 <type>anyrange
</type> <literal>&<</literal> <type>anyrange
</type>
20704 <returnvalue>boolean
</returnvalue>
20707 Does the first range not extend to the right of the second?
20710 <literal>int8range(
1,
20)
&< int8range(
18,
20)
</literal>
20711 <returnvalue>t
</returnvalue>
20716 <entry role=
"func_table_entry"><para role=
"func_signature">
20717 <type>anyrange
</type> <literal>&></literal> <type>anyrange
</type>
20718 <returnvalue>boolean
</returnvalue>
20721 Does the first range not extend to the left of the second?
20724 <literal>int8range(
7,
20)
&> int8range(
5,
10)
</literal>
20725 <returnvalue>t
</returnvalue>
20730 <entry role=
"func_table_entry"><para role=
"func_signature">
20731 <type>anyrange
</type> <literal>-|-
</literal> <type>anyrange
</type>
20732 <returnvalue>boolean
</returnvalue>
20735 Are the ranges adjacent?
20738 <literal>numrange(
1.1,
2.2) -|- numrange(
2.2,
3.3)
</literal>
20739 <returnvalue>t
</returnvalue>
20744 <entry role=
"func_table_entry"><para role=
"func_signature">
20745 <type>anyrange
</type> <literal>+
</literal> <type>anyrange
</type>
20746 <returnvalue>anyrange
</returnvalue>
20749 Computes the union of the ranges. The ranges must overlap or be
20750 adjacent, so that the union is a single range (but
20751 see
<function>range_merge()
</function>).
20754 <literal>numrange(
5,
15) + numrange(
10,
20)
</literal>
20755 <returnvalue>[
5,
20)
</returnvalue>
20760 <entry role=
"func_table_entry"><para role=
"func_signature">
20761 <type>anyrange
</type> <literal>*
</literal> <type>anyrange
</type>
20762 <returnvalue>anyrange
</returnvalue>
20765 Computes the intersection of the ranges.
20768 <literal>int8range(
5,
15) * int8range(
10,
20)
</literal>
20769 <returnvalue>[
10,
15)
</returnvalue>
20774 <entry role=
"func_table_entry"><para role=
"func_signature">
20775 <type>anyrange
</type> <literal>-
</literal> <type>anyrange
</type>
20776 <returnvalue>anyrange
</returnvalue>
20779 Computes the difference of the ranges. The second range must not be
20780 contained in the first in such a way that the difference would not be
20784 <literal>int8range(
5,
15) - int8range(
10,
20)
</literal>
20785 <returnvalue>[
5,
10)
</returnvalue>
20792 <table id=
"multirange-operators-table">
20793 <title>Multirange Operators
</title>
20797 <entry role=
"func_table_entry"><para role=
"func_signature">
20811 <entry role=
"func_table_entry"><para role=
"func_signature">
20812 <type>anymultirange
</type> <literal>@
></literal> <type>anymultirange
</type>
20813 <returnvalue>boolean
</returnvalue>
20816 Does the first multirange contain the second?
20819 <literal>'{[
2,
4)}'::int4multirange @
> '{[
2,
3)}'::int4multirange
</literal>
20820 <returnvalue>t
</returnvalue>
20825 <entry role=
"func_table_entry"><para role=
"func_signature">
20826 <type>anymultirange
</type> <literal>@
></literal> <type>anyrange
</type>
20827 <returnvalue>boolean
</returnvalue>
20830 Does the multirange contain the range?
20833 <literal>'{[
2,
4)}'::int4multirange @
> int4range(
2,
3)
</literal>
20834 <returnvalue>t
</returnvalue>
20839 <entry role=
"func_table_entry"><para role=
"func_signature">
20840 <type>anymultirange
</type> <literal>@
></literal> <type>anyelement
</type>
20841 <returnvalue>boolean
</returnvalue>
20844 Does the multirange contain the element?
20847 <literal>'{[
2011-
01-
01,
2011-
03-
01)}'::tsmultirange @
> '
2011-
01-
10'::timestamp
</literal>
20848 <returnvalue>t
</returnvalue>
20853 <entry role=
"func_table_entry"><para role=
"func_signature">
20854 <type>anyrange
</type> <literal>@
></literal> <type>anymultirange
</type>
20855 <returnvalue>boolean
</returnvalue>
20858 Does the range contain the multirange?
20861 <literal>'[
2,
4)'::int4range @
> '{[
2,
3)}'::int4multirange
</literal>
20862 <returnvalue>t
</returnvalue>
20867 <entry role=
"func_table_entry"><para role=
"func_signature">
20868 <type>anymultirange
</type> <literal><@
</literal> <type>anymultirange
</type>
20869 <returnvalue>boolean
</returnvalue>
20872 Is the first multirange contained by the second?
20875 <literal>'{[
2,
4)}'::int4multirange
<@ '{[
1,
7)}'::int4multirange
</literal>
20876 <returnvalue>t
</returnvalue>
20881 <entry role=
"func_table_entry"><para role=
"func_signature">
20882 <type>anymultirange
</type> <literal><@
</literal> <type>anyrange
</type>
20883 <returnvalue>boolean
</returnvalue>
20886 Is the multirange contained by the range?
20889 <literal>'{[
2,
4)}'::int4multirange
<@ int4range(
1,
7)
</literal>
20890 <returnvalue>t
</returnvalue>
20895 <entry role=
"func_table_entry"><para role=
"func_signature">
20896 <type>anyrange
</type> <literal><@
</literal> <type>anymultirange
</type>
20897 <returnvalue>boolean
</returnvalue>
20900 Is the range contained by the multirange?
20903 <literal>int4range(
2,
4)
<@ '{[
1,
7)}'::int4multirange
</literal>
20904 <returnvalue>t
</returnvalue>
20909 <entry role=
"func_table_entry"><para role=
"func_signature">
20910 <type>anyelement
</type> <literal><@
</literal> <type>anymultirange
</type>
20911 <returnvalue>boolean
</returnvalue>
20914 Is the element contained by the multirange?
20917 <literal>4 <@ '{[
1,
7)}'::int4multirange
</literal>
20918 <returnvalue>t
</returnvalue>
20923 <entry role=
"func_table_entry"><para role=
"func_signature">
20924 <type>anymultirange
</type> <literal>&&</literal> <type>anymultirange
</type>
20925 <returnvalue>boolean
</returnvalue>
20928 Do the multiranges overlap, that is, have any elements in common?
20931 <literal>'{[
3,
7)}'::int8multirange
&& '{[
4,
12)}'::int8multirange
</literal>
20932 <returnvalue>t
</returnvalue>
20937 <entry role=
"func_table_entry"><para role=
"func_signature">
20938 <type>anymultirange
</type> <literal>&&</literal> <type>anyrange
</type>
20939 <returnvalue>boolean
</returnvalue>
20942 Does the multirange overlap the range?
20945 <literal>'{[
3,
7)}'::int8multirange
&& int8range(
4,
12)
</literal>
20946 <returnvalue>t
</returnvalue>
20951 <entry role=
"func_table_entry"><para role=
"func_signature">
20952 <type>anyrange
</type> <literal>&&</literal> <type>anymultirange
</type>
20953 <returnvalue>boolean
</returnvalue>
20956 Does the range overlap the multirange?
20959 <literal>int8range(
3,
7)
&& '{[
4,
12)}'::int8multirange
</literal>
20960 <returnvalue>t
</returnvalue>
20965 <entry role=
"func_table_entry"><para role=
"func_signature">
20966 <type>anymultirange
</type> <literal><<</literal> <type>anymultirange
</type>
20967 <returnvalue>boolean
</returnvalue>
20970 Is the first multirange strictly left of the second?
20973 <literal>'{[
1,
10)}'::int8multirange
<< '{[
100,
110)}'::int8multirange
</literal>
20974 <returnvalue>t
</returnvalue>
20979 <entry role=
"func_table_entry"><para role=
"func_signature">
20980 <type>anymultirange
</type> <literal><<</literal> <type>anyrange
</type>
20981 <returnvalue>boolean
</returnvalue>
20984 Is the multirange strictly left of the range?
20987 <literal>'{[
1,
10)}'::int8multirange
<< int8range(
100,
110)
</literal>
20988 <returnvalue>t
</returnvalue>
20993 <entry role=
"func_table_entry"><para role=
"func_signature">
20994 <type>anyrange
</type> <literal><<</literal> <type>anymultirange
</type>
20995 <returnvalue>boolean
</returnvalue>
20998 Is the range strictly left of the multirange?
21001 <literal>int8range(
1,
10)
<< '{[
100,
110)}'::int8multirange
</literal>
21002 <returnvalue>t
</returnvalue>
21007 <entry role=
"func_table_entry"><para role=
"func_signature">
21008 <type>anymultirange
</type> <literal>>></literal> <type>anymultirange
</type>
21009 <returnvalue>boolean
</returnvalue>
21012 Is the first multirange strictly right of the second?
21015 <literal>'{[
50,
60)}'::int8multirange
>> '{[
20,
30)}'::int8multirange
</literal>
21016 <returnvalue>t
</returnvalue>
21021 <entry role=
"func_table_entry"><para role=
"func_signature">
21022 <type>anymultirange
</type> <literal>>></literal> <type>anyrange
</type>
21023 <returnvalue>boolean
</returnvalue>
21026 Is the multirange strictly right of the range?
21029 <literal>'{[
50,
60)}'::int8multirange
>> int8range(
20,
30)
</literal>
21030 <returnvalue>t
</returnvalue>
21035 <entry role=
"func_table_entry"><para role=
"func_signature">
21036 <type>anyrange
</type> <literal>>></literal> <type>anymultirange
</type>
21037 <returnvalue>boolean
</returnvalue>
21040 Is the range strictly right of the multirange?
21043 <literal>int8range(
50,
60)
>> '{[
20,
30)}'::int8multirange
</literal>
21044 <returnvalue>t
</returnvalue>
21049 <entry role=
"func_table_entry"><para role=
"func_signature">
21050 <type>anymultirange
</type> <literal>&<</literal> <type>anymultirange
</type>
21051 <returnvalue>boolean
</returnvalue>
21054 Does the first multirange not extend to the right of the second?
21057 <literal>'{[
1,
20)}'::int8multirange
&< '{[
18,
20)}'::int8multirange
</literal>
21058 <returnvalue>t
</returnvalue>
21063 <entry role=
"func_table_entry"><para role=
"func_signature">
21064 <type>anymultirange
</type> <literal>&<</literal> <type>anyrange
</type>
21065 <returnvalue>boolean
</returnvalue>
21068 Does the multirange not extend to the right of the range?
21071 <literal>'{[
1,
20)}'::int8multirange
&< int8range(
18,
20)
</literal>
21072 <returnvalue>t
</returnvalue>
21077 <entry role=
"func_table_entry"><para role=
"func_signature">
21078 <type>anyrange
</type> <literal>&<</literal> <type>anymultirange
</type>
21079 <returnvalue>boolean
</returnvalue>
21082 Does the range not extend to the right of the multirange?
21085 <literal>int8range(
1,
20)
&< '{[
18,
20)}'::int8multirange
</literal>
21086 <returnvalue>t
</returnvalue>
21091 <entry role=
"func_table_entry"><para role=
"func_signature">
21092 <type>anymultirange
</type> <literal>&></literal> <type>anymultirange
</type>
21093 <returnvalue>boolean
</returnvalue>
21096 Does the first multirange not extend to the left of the second?
21099 <literal>'{[
7,
20)}'::int8multirange
&> '{[
5,
10)}'::int8multirange
</literal>
21100 <returnvalue>t
</returnvalue>
21105 <entry role=
"func_table_entry"><para role=
"func_signature">
21106 <type>anymultirange
</type> <literal>&></literal> <type>anyrange
</type>
21107 <returnvalue>boolean
</returnvalue>
21110 Does the multirange not extend to the left of the range?
21113 <literal>'{[
7,
20)}'::int8multirange
&> int8range(
5,
10)
</literal>
21114 <returnvalue>t
</returnvalue>
21119 <entry role=
"func_table_entry"><para role=
"func_signature">
21120 <type>anyrange
</type> <literal>&></literal> <type>anymultirange
</type>
21121 <returnvalue>boolean
</returnvalue>
21124 Does the range not extend to the left of the multirange?
21127 <literal>int8range(
7,
20)
&> '{[
5,
10)}'::int8multirange
</literal>
21128 <returnvalue>t
</returnvalue>
21133 <entry role=
"func_table_entry"><para role=
"func_signature">
21134 <type>anymultirange
</type> <literal>-|-
</literal> <type>anymultirange
</type>
21135 <returnvalue>boolean
</returnvalue>
21138 Are the multiranges adjacent?
21141 <literal>'{[
1.1,
2.2)}'::nummultirange -|- '{[
2.2,
3.3)}'::nummultirange
</literal>
21142 <returnvalue>t
</returnvalue>
21147 <entry role=
"func_table_entry"><para role=
"func_signature">
21148 <type>anymultirange
</type> <literal>-|-
</literal> <type>anyrange
</type>
21149 <returnvalue>boolean
</returnvalue>
21152 Is the multirange adjacent to the range?
21155 <literal>'{[
1.1,
2.2)}'::nummultirange -|- numrange(
2.2,
3.3)
</literal>
21156 <returnvalue>t
</returnvalue>
21161 <entry role=
"func_table_entry"><para role=
"func_signature">
21162 <type>anyrange
</type> <literal>-|-
</literal> <type>anymultirange
</type>
21163 <returnvalue>boolean
</returnvalue>
21166 Is the range adjacent to the multirange?
21169 <literal>numrange(
1.1,
2.2) -|- '{[
2.2,
3.3)}'::nummultirange
</literal>
21170 <returnvalue>t
</returnvalue>
21175 <entry role=
"func_table_entry"><para role=
"func_signature">
21176 <type>anymultirange
</type> <literal>+
</literal> <type>anymultirange
</type>
21177 <returnvalue>anymultirange
</returnvalue>
21180 Computes the union of the multiranges. The multiranges need not overlap
21184 <literal>'{[
5,
10)}'::nummultirange + '{[
15,
20)}'::nummultirange
</literal>
21185 <returnvalue>{[
5,
10), [
15,
20)}
</returnvalue>
21190 <entry role=
"func_table_entry"><para role=
"func_signature">
21191 <type>anymultirange
</type> <literal>*
</literal> <type>anymultirange
</type>
21192 <returnvalue>anymultirange
</returnvalue>
21195 Computes the intersection of the multiranges.
21198 <literal>'{[
5,
15)}'::int8multirange * '{[
10,
20)}'::int8multirange
</literal>
21199 <returnvalue>{[
10,
15)}
</returnvalue>
21204 <entry role=
"func_table_entry"><para role=
"func_signature">
21205 <type>anymultirange
</type> <literal>-
</literal> <type>anymultirange
</type>
21206 <returnvalue>anymultirange
</returnvalue>
21209 Computes the difference of the multiranges.
21212 <literal>'{[
5,
20)}'::int8multirange - '{[
10,
15)}'::int8multirange
</literal>
21213 <returnvalue>{[
5,
10), [
15,
20)}
</returnvalue>
21221 The left-of/right-of/adjacent operators always return false when an empty
21222 range or multirange is involved; that is, an empty range is not considered to
21223 be either before or after any other range.
21227 Elsewhere empty ranges and multiranges are treated as the additive identity:
21228 anything unioned with an empty value is itself. Anything minus an empty
21229 value is itself. An empty multirange has exactly the same points as an empty
21230 range. Every range contains the empty range. Every multirange contains as many
21231 empty ranges as you like.
21235 The range union and difference operators will fail if the resulting range would
21236 need to contain two disjoint sub-ranges, as such a range cannot be
21237 represented. There are separate operators for union and difference that take
21238 multirange parameters and return a multirange, and they do not fail even if
21239 their arguments are disjoint. So if you need a union or difference operation
21240 for ranges that may be disjoint, you can avoid errors by first casting your
21241 ranges to multiranges.
21245 <xref linkend=
"range-functions-table"/> shows the functions
21246 available for use with range types.
21247 <xref linkend=
"multirange-functions-table"/> shows the functions
21248 available for use with multirange types.
21251 <table id=
"range-functions-table">
21252 <title>Range Functions
</title>
21256 <entry role=
"func_table_entry"><para role=
"func_signature">
21270 <entry role=
"func_table_entry"><para role=
"func_signature">
21272 <primary>lower
</primary>
21274 <function>lower
</function> (
<type>anyrange
</type> )
21275 <returnvalue>anyelement
</returnvalue>
21278 Extracts the lower bound of the range (
<literal>NULL
</literal> if the
21279 range is empty or has no lower bound).
21282 <literal>lower(numrange(
1.1,
2.2))
</literal>
21283 <returnvalue>1.1</returnvalue>
21288 <entry role=
"func_table_entry"><para role=
"func_signature">
21290 <primary>upper
</primary>
21292 <function>upper
</function> (
<type>anyrange
</type> )
21293 <returnvalue>anyelement
</returnvalue>
21296 Extracts the upper bound of the range (
<literal>NULL
</literal> if the
21297 range is empty or has no upper bound).
21300 <literal>upper(numrange(
1.1,
2.2))
</literal>
21301 <returnvalue>2.2</returnvalue>
21306 <entry role=
"func_table_entry"><para role=
"func_signature">
21308 <primary>isempty
</primary>
21310 <function>isempty
</function> (
<type>anyrange
</type> )
21311 <returnvalue>boolean
</returnvalue>
21314 Is the range empty?
21317 <literal>isempty(numrange(
1.1,
2.2))
</literal>
21318 <returnvalue>f
</returnvalue>
21323 <entry role=
"func_table_entry"><para role=
"func_signature">
21325 <primary>lower_inc
</primary>
21327 <function>lower_inc
</function> (
<type>anyrange
</type> )
21328 <returnvalue>boolean
</returnvalue>
21331 Is the range's lower bound inclusive?
21334 <literal>lower_inc(numrange(
1.1,
2.2))
</literal>
21335 <returnvalue>t
</returnvalue>
21340 <entry role=
"func_table_entry"><para role=
"func_signature">
21342 <primary>upper_inc
</primary>
21344 <function>upper_inc
</function> (
<type>anyrange
</type> )
21345 <returnvalue>boolean
</returnvalue>
21348 Is the range's upper bound inclusive?
21351 <literal>upper_inc(numrange(
1.1,
2.2))
</literal>
21352 <returnvalue>f
</returnvalue>
21357 <entry role=
"func_table_entry"><para role=
"func_signature">
21359 <primary>lower_inf
</primary>
21361 <function>lower_inf
</function> (
<type>anyrange
</type> )
21362 <returnvalue>boolean
</returnvalue>
21365 Does the range have no lower bound? (A lower bound of
21366 <literal>-Infinity
</literal> returns false.)
21369 <literal>lower_inf('(,)'::daterange)
</literal>
21370 <returnvalue>t
</returnvalue>
21375 <entry role=
"func_table_entry"><para role=
"func_signature">
21377 <primary>upper_inf
</primary>
21379 <function>upper_inf
</function> (
<type>anyrange
</type> )
21380 <returnvalue>boolean
</returnvalue>
21383 Does the range have no upper bound? (An upper bound of
21384 <literal>Infinity
</literal> returns false.)
21387 <literal>upper_inf('(,)'::daterange)
</literal>
21388 <returnvalue>t
</returnvalue>
21393 <entry role=
"func_table_entry"><para role=
"func_signature">
21395 <primary>range_merge
</primary>
21397 <function>range_merge
</function> (
<type>anyrange
</type>,
<type>anyrange
</type> )
21398 <returnvalue>anyrange
</returnvalue>
21401 Computes the smallest range that includes both of the given ranges.
21404 <literal>range_merge('[
1,
2)'::int4range, '[
3,
4)'::int4range)
</literal>
21405 <returnvalue>[
1,
4)
</returnvalue>
21412 <table id=
"multirange-functions-table">
21413 <title>Multirange Functions
</title>
21417 <entry role=
"func_table_entry"><para role=
"func_signature">
21430 <entry role=
"func_table_entry"><para role=
"func_signature">
21432 <primary>lower
</primary>
21434 <function>lower
</function> (
<type>anymultirange
</type> )
21435 <returnvalue>anyelement
</returnvalue>
21438 Extracts the lower bound of the multirange (
<literal>NULL
</literal> if the
21439 multirange is empty has no lower bound).
21442 <literal>lower('{[
1.1,
2.2)}'::nummultirange)
</literal>
21443 <returnvalue>1.1</returnvalue>
21448 <entry role=
"func_table_entry"><para role=
"func_signature">
21450 <primary>upper
</primary>
21452 <function>upper
</function> (
<type>anymultirange
</type> )
21453 <returnvalue>anyelement
</returnvalue>
21456 Extracts the upper bound of the multirange (
<literal>NULL
</literal> if the
21457 multirange is empty or has no upper bound).
21460 <literal>upper('{[
1.1,
2.2)}'::nummultirange)
</literal>
21461 <returnvalue>2.2</returnvalue>
21466 <entry role=
"func_table_entry"><para role=
"func_signature">
21468 <primary>isempty
</primary>
21470 <function>isempty
</function> (
<type>anymultirange
</type> )
21471 <returnvalue>boolean
</returnvalue>
21474 Is the multirange empty?
21477 <literal>isempty('{[
1.1,
2.2)}'::nummultirange)
</literal>
21478 <returnvalue>f
</returnvalue>
21483 <entry role=
"func_table_entry"><para role=
"func_signature">
21485 <primary>lower_inc
</primary>
21487 <function>lower_inc
</function> (
<type>anymultirange
</type> )
21488 <returnvalue>boolean
</returnvalue>
21491 Is the multirange's lower bound inclusive?
21494 <literal>lower_inc('{[
1.1,
2.2)}'::nummultirange)
</literal>
21495 <returnvalue>t
</returnvalue>
21500 <entry role=
"func_table_entry"><para role=
"func_signature">
21502 <primary>upper_inc
</primary>
21504 <function>upper_inc
</function> (
<type>anymultirange
</type> )
21505 <returnvalue>boolean
</returnvalue>
21508 Is the multirange's upper bound inclusive?
21511 <literal>upper_inc('{[
1.1,
2.2)}'::nummultirange)
</literal>
21512 <returnvalue>f
</returnvalue>
21517 <entry role=
"func_table_entry"><para role=
"func_signature">
21519 <primary>lower_inf
</primary>
21521 <function>lower_inf
</function> (
<type>anymultirange
</type> )
21522 <returnvalue>boolean
</returnvalue>
21525 Does the multirange have no lower bound? (A lower bound of
21526 <literal>-Infinity
</literal> returns false.)
21529 <literal>lower_inf('{(,)}'::datemultirange)
</literal>
21530 <returnvalue>t
</returnvalue>
21535 <entry role=
"func_table_entry"><para role=
"func_signature">
21537 <primary>upper_inf
</primary>
21539 <function>upper_inf
</function> (
<type>anymultirange
</type> )
21540 <returnvalue>boolean
</returnvalue>
21543 Does the multirange have no upper bound? (An upper bound of
21544 <literal>Infinity
</literal> returns false.)
21547 <literal>upper_inf('{(,)}'::datemultirange)
</literal>
21548 <returnvalue>t
</returnvalue>
21553 <entry role=
"func_table_entry"><para role=
"func_signature">
21555 <primary>range_merge
</primary>
21557 <function>range_merge
</function> (
<type>anymultirange
</type> )
21558 <returnvalue>anyrange
</returnvalue>
21561 Computes the smallest range that includes the entire multirange.
21564 <literal>range_merge('{[
1,
2), [
3,
4)}'::int4multirange)
</literal>
21565 <returnvalue>[
1,
4)
</returnvalue>
21570 <entry role=
"func_table_entry"><para role=
"func_signature">
21572 <primary>multirange (function)
</primary>
21574 <function>multirange
</function> (
<type>anyrange
</type> )
21575 <returnvalue>anymultirange
</returnvalue>
21578 Returns a multirange containing just the given range.
21581 <literal>multirange('[
1,
2)'::int4range)
</literal>
21582 <returnvalue>{[
1,
2)}
</returnvalue>
21587 <entry role=
"func_table_entry"><para role=
"func_signature">
21589 <primary>unnest
</primary>
21590 <secondary>for multirange
</secondary>
21592 <function>unnest
</function> (
<type>anymultirange
</type> )
21593 <returnvalue>setof anyrange
</returnvalue>
21596 Expands a multirange into a set of ranges in ascending order.
21599 <literal>unnest('{[
1,
2), [
3,
4)}'::int4multirange)
</literal>
21600 <returnvalue></returnvalue>
21612 The
<function>lower_inc
</function>,
<function>upper_inc
</function>,
21613 <function>lower_inf
</function>, and
<function>upper_inf
</function>
21614 functions all return false for an empty range or multirange.
21618 <sect1 id=
"functions-aggregate">
21619 <title>Aggregate Functions
</title>
21621 <indexterm zone=
"functions-aggregate">
21622 <primary>aggregate function
</primary>
21623 <secondary>built-in
</secondary>
21627 <firstterm>Aggregate functions
</firstterm> compute a single result
21628 from a set of input values. The built-in general-purpose aggregate
21629 functions are listed in
<xref linkend=
"functions-aggregate-table"/>
21630 while statistical aggregates are in
<xref
21631 linkend=
"functions-aggregate-statistics-table"/>.
21632 The built-in within-group ordered-set aggregate functions
21633 are listed in
<xref linkend=
"functions-orderedset-table"/>
21634 while the built-in within-group hypothetical-set ones are in
<xref
21635 linkend=
"functions-hypothetical-table"/>. Grouping operations,
21636 which are closely related to aggregate functions, are listed in
21637 <xref linkend=
"functions-grouping-table"/>.
21638 The special syntax considerations for aggregate
21639 functions are explained in
<xref linkend=
"syntax-aggregates"/>.
21640 Consult
<xref linkend=
"tutorial-agg"/> for additional introductory
21645 Aggregate functions that support
<firstterm>Partial Mode
</firstterm>
21646 are eligible to participate in various optimizations, such as parallel
21651 While all aggregates below accept an optional
21652 <literal>ORDER BY
</literal> clause (as outlined in
<xref
21653 linkend=
"syntax-aggregates"/>), the clause has only been added to
21654 aggregates whose output is affected by ordering.
21657 <table id=
"functions-aggregate-table">
21658 <title>General-Purpose Aggregate Functions
</title>
21660 <colspec colname=
"col1" colwidth=
"10*"/>
21661 <colspec colname=
"col2" colwidth=
"1*"/>
21664 <entry role=
"func_table_entry"><para role=
"func_signature">
21670 <entry>Partial Mode
</entry>
21676 <entry role=
"func_table_entry"><para role=
"func_signature">
21678 <primary>any_value
</primary>
21680 <function>any_value
</function> (
<type>anyelement
</type> )
21681 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
21684 Returns an arbitrary value from the non-null input values.
21690 <entry role=
"func_table_entry"><para role=
"func_signature">
21692 <primary>array_agg
</primary>
21694 <function>array_agg
</function> (
<type>anynonarray
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21695 <returnvalue>anyarray
</returnvalue>
21698 Collects all the input values, including nulls, into an array.
21704 <entry role=
"func_table_entry"><para role=
"func_signature">
21705 <function>array_agg
</function> (
<type>anyarray
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21706 <returnvalue>anyarray
</returnvalue>
21709 Concatenates all the input arrays into an array of one higher
21710 dimension. (The inputs must all have the same dimensionality, and
21711 cannot be empty or null.)
21717 <entry role=
"func_table_entry"><para role=
"func_signature">
21719 <primary>average
</primary>
21722 <primary>avg
</primary>
21724 <function>avg
</function> (
<type>smallint
</type> )
21725 <returnvalue>numeric
</returnvalue>
21727 <para role=
"func_signature">
21728 <function>avg
</function> (
<type>integer
</type> )
21729 <returnvalue>numeric
</returnvalue>
21731 <para role=
"func_signature">
21732 <function>avg
</function> (
<type>bigint
</type> )
21733 <returnvalue>numeric
</returnvalue>
21735 <para role=
"func_signature">
21736 <function>avg
</function> (
<type>numeric
</type> )
21737 <returnvalue>numeric
</returnvalue>
21739 <para role=
"func_signature">
21740 <function>avg
</function> (
<type>real
</type> )
21741 <returnvalue>double precision
</returnvalue>
21743 <para role=
"func_signature">
21744 <function>avg
</function> (
<type>double precision
</type> )
21745 <returnvalue>double precision
</returnvalue>
21747 <para role=
"func_signature">
21748 <function>avg
</function> (
<type>interval
</type> )
21749 <returnvalue>interval
</returnvalue>
21752 Computes the average (arithmetic mean) of all the non-null input
21759 <entry role=
"func_table_entry"><para role=
"func_signature">
21761 <primary>bit_and
</primary>
21763 <function>bit_and
</function> (
<type>smallint
</type> )
21764 <returnvalue>smallint
</returnvalue>
21766 <para role=
"func_signature">
21767 <function>bit_and
</function> (
<type>integer
</type> )
21768 <returnvalue>integer
</returnvalue>
21770 <para role=
"func_signature">
21771 <function>bit_and
</function> (
<type>bigint
</type> )
21772 <returnvalue>bigint
</returnvalue>
21774 <para role=
"func_signature">
21775 <function>bit_and
</function> (
<type>bit
</type> )
21776 <returnvalue>bit
</returnvalue>
21779 Computes the bitwise AND of all non-null input values.
21785 <entry role=
"func_table_entry"><para role=
"func_signature">
21787 <primary>bit_or
</primary>
21789 <function>bit_or
</function> (
<type>smallint
</type> )
21790 <returnvalue>smallint
</returnvalue>
21792 <para role=
"func_signature">
21793 <function>bit_or
</function> (
<type>integer
</type> )
21794 <returnvalue>integer
</returnvalue>
21796 <para role=
"func_signature">
21797 <function>bit_or
</function> (
<type>bigint
</type> )
21798 <returnvalue>bigint
</returnvalue>
21800 <para role=
"func_signature">
21801 <function>bit_or
</function> (
<type>bit
</type> )
21802 <returnvalue>bit
</returnvalue>
21805 Computes the bitwise OR of all non-null input values.
21811 <entry role=
"func_table_entry"><para role=
"func_signature">
21813 <primary>bit_xor
</primary>
21815 <function>bit_xor
</function> (
<type>smallint
</type> )
21816 <returnvalue>smallint
</returnvalue>
21818 <para role=
"func_signature">
21819 <function>bit_xor
</function> (
<type>integer
</type> )
21820 <returnvalue>integer
</returnvalue>
21822 <para role=
"func_signature">
21823 <function>bit_xor
</function> (
<type>bigint
</type> )
21824 <returnvalue>bigint
</returnvalue>
21826 <para role=
"func_signature">
21827 <function>bit_xor
</function> (
<type>bit
</type> )
21828 <returnvalue>bit
</returnvalue>
21831 Computes the bitwise exclusive OR of all non-null input values.
21832 Can be useful as a checksum for an unordered set of values.
21838 <entry role=
"func_table_entry"><para role=
"func_signature">
21840 <primary>bool_and
</primary>
21842 <function>bool_and
</function> (
<type>boolean
</type> )
21843 <returnvalue>boolean
</returnvalue>
21846 Returns true if all non-null input values are true, otherwise false.
21852 <entry role=
"func_table_entry"><para role=
"func_signature">
21854 <primary>bool_or
</primary>
21856 <function>bool_or
</function> (
<type>boolean
</type> )
21857 <returnvalue>boolean
</returnvalue>
21860 Returns true if any non-null input value is true, otherwise false.
21866 <entry role=
"func_table_entry"><para role=
"func_signature">
21868 <primary>count
</primary>
21870 <function>count
</function> (
<literal>*
</literal> )
21871 <returnvalue>bigint
</returnvalue>
21874 Computes the number of input rows.
21880 <entry role=
"func_table_entry"><para role=
"func_signature">
21881 <function>count
</function> (
<type>"any"</type> )
21882 <returnvalue>bigint
</returnvalue>
21885 Computes the number of input rows in which the input value is not
21892 <entry role=
"func_table_entry"><para role=
"func_signature">
21894 <primary>every
</primary>
21896 <function>every
</function> (
<type>boolean
</type> )
21897 <returnvalue>boolean
</returnvalue>
21900 This is the SQL standard's equivalent to
<function>bool_and
</function>.
21906 <entry role=
"func_table_entry"><para role=
"func_signature">
21908 <primary>json_agg
</primary>
21910 <function>json_agg
</function> (
<type>anyelement
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21911 <returnvalue>json
</returnvalue>
21913 <para role=
"func_signature">
21915 <primary>jsonb_agg
</primary>
21917 <function>jsonb_agg
</function> (
<type>anyelement
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21918 <returnvalue>jsonb
</returnvalue>
21921 Collects all the input values, including nulls, into a JSON array.
21922 Values are converted to JSON as per
<function>to_json
</function>
21923 or
<function>to_jsonb
</function>.
21929 <entry role=
"func_table_entry"><para role=
"func_signature">
21931 <primary>json_agg_strict
</primary>
21933 <function>json_agg_strict
</function> (
<type>anyelement
</type> )
21934 <returnvalue>json
</returnvalue>
21936 <para role=
"func_signature">
21938 <primary>jsonb_agg_strict
</primary>
21940 <function>jsonb_agg_strict
</function> (
<type>anyelement
</type> )
21941 <returnvalue>jsonb
</returnvalue>
21944 Collects all the input values, skipping nulls, into a JSON array.
21945 Values are converted to JSON as per
<function>to_json
</function>
21946 or
<function>to_jsonb
</function>.
21952 <entry role=
"func_table_entry"><para role=
"func_signature">
21953 <indexterm><primary>json_arrayagg
</primary></indexterm>
21954 <function>json_arrayagg
</function> (
21955 <optional> <replaceable>value_expression
</replaceable> </optional>
21956 <optional> <literal>ORDER BY
</literal> <replaceable>sort_expression
</replaceable> </optional>
21957 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
21958 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
21961 Behaves in the same way as
<function>json_array
</function>
21962 but as an aggregate function so it only takes one
21963 <replaceable>value_expression
</replaceable> parameter.
21964 If
<literal>ABSENT ON NULL
</literal> is specified, any NULL
21965 values are omitted.
21966 If
<literal>ORDER BY
</literal> is specified, the elements will
21967 appear in the array in that order rather than in the input order.
21970 <literal>SELECT json_arrayagg(v) FROM (VALUES(
2),(
1)) t(v)
</literal>
21971 <returnvalue>[
2,
1]
</returnvalue>
21977 <entry role=
"func_table_entry"><para role=
"func_signature">
21978 <indexterm><primary>json_objectagg
</primary></indexterm>
21979 <function>json_objectagg
</function> (
21980 <optional> {
<replaceable>key_expression
</replaceable> {
<literal>VALUE
</literal> | ':' }
<replaceable>value_expression
</replaceable> }
</optional>
21981 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
21982 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional> </optional>
21983 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
21986 Behaves like
<function>json_object
</function><!-- xref -->, but as an
21987 aggregate function, so it only takes one
21988 <replaceable>key_expression
</replaceable> and one
21989 <replaceable>value_expression
</replaceable> parameter.
21992 <literal>SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date +
1)) AS t(k,v)
</literal>
21993 <returnvalue>{
"a" :
"2022-05-10",
"b" :
"2022-05-11" }
</returnvalue>
21999 <entry role=
"func_table_entry"><para role=
"func_signature">
22001 <primary>json_object_agg
</primary>
22003 <function>json_object_agg
</function> (
<parameter>key
</parameter>
22004 <type>"any"</type>,
<parameter>value
</parameter>
22006 <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22007 <returnvalue>json
</returnvalue>
22009 <para role=
"func_signature">
22011 <primary>jsonb_object_agg
</primary>
22013 <function>jsonb_object_agg
</function> (
<parameter>key
</parameter>
22014 <type>"any"</type>,
<parameter>value
</parameter>
22016 <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22017 <returnvalue>jsonb
</returnvalue>
22020 Collects all the key/value pairs into a JSON object. Key arguments
22021 are coerced to text; value arguments are converted as per
22022 <function>to_json
</function> or
<function>to_jsonb
</function>.
22023 Values can be null, but keys cannot.
22029 <entry role=
"func_table_entry"><para role=
"func_signature">
22031 <primary>json_object_agg_strict
</primary>
22033 <function>json_object_agg_strict
</function> (
22034 <parameter>key
</parameter> <type>"any"</type>,
22035 <parameter>value
</parameter> <type>"any"</type> )
22036 <returnvalue>json
</returnvalue>
22038 <para role=
"func_signature">
22040 <primary>jsonb_object_agg_strict
</primary>
22042 <function>jsonb_object_agg_strict
</function> (
22043 <parameter>key
</parameter> <type>"any"</type>,
22044 <parameter>value
</parameter> <type>"any"</type> )
22045 <returnvalue>jsonb
</returnvalue>
22048 Collects all the key/value pairs into a JSON object. Key arguments
22049 are coerced to text; value arguments are converted as per
22050 <function>to_json
</function> or
<function>to_jsonb
</function>.
22051 The
<parameter>key
</parameter> can not be null. If the
22052 <parameter>value
</parameter> is null then the entry is skipped,
22058 <entry role=
"func_table_entry"><para role=
"func_signature">
22060 <primary>json_object_agg_unique
</primary>
22062 <function>json_object_agg_unique
</function> (
22063 <parameter>key
</parameter> <type>"any"</type>,
22064 <parameter>value
</parameter> <type>"any"</type> )
22065 <returnvalue>json
</returnvalue>
22067 <para role=
"func_signature">
22069 <primary>jsonb_object_agg_unique
</primary>
22071 <function>jsonb_object_agg_unique
</function> (
22072 <parameter>key
</parameter> <type>"any"</type>,
22073 <parameter>value
</parameter> <type>"any"</type> )
22074 <returnvalue>jsonb
</returnvalue>
22077 Collects all the key/value pairs into a JSON object. Key arguments
22078 are coerced to text; value arguments are converted as per
22079 <function>to_json
</function> or
<function>to_jsonb
</function>.
22080 Values can be null, but keys cannot.
22081 If there is a duplicate key an error is thrown.
22087 <entry role=
"func_table_entry"><para role=
"func_signature">
22089 <primary>json_object_agg_unique_strict
</primary>
22091 <function>json_object_agg_unique_strict
</function> (
22092 <parameter>key
</parameter> <type>"any"</type>,
22093 <parameter>value
</parameter> <type>"any"</type> )
22094 <returnvalue>json
</returnvalue>
22096 <para role=
"func_signature">
22098 <primary>jsonb_object_agg_unique_strict
</primary>
22100 <function>jsonb_object_agg_unique_strict
</function> (
22101 <parameter>key
</parameter> <type>"any"</type>,
22102 <parameter>value
</parameter> <type>"any"</type> )
22103 <returnvalue>jsonb
</returnvalue>
22106 Collects all the key/value pairs into a JSON object. Key arguments
22107 are coerced to text; value arguments are converted as per
22108 <function>to_json
</function> or
<function>to_jsonb
</function>.
22109 The
<parameter>key
</parameter> can not be null. If the
22110 <parameter>value
</parameter> is null then the entry is skipped.
22111 If there is a duplicate key an error is thrown.
22117 <entry role=
"func_table_entry"><para role=
"func_signature">
22119 <primary>max
</primary>
22121 <function>max
</function> (
<replaceable>see text
</replaceable> )
22122 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
22125 Computes the maximum of the non-null input
22126 values. Available for any numeric, string, date/time, or enum type,
22127 as well as
<type>inet
</type>,
<type>interval
</type>,
22128 <type>money
</type>,
<type>oid
</type>,
<type>pg_lsn
</type>,
22129 <type>tid
</type>,
<type>xid8
</type>,
22130 and also arrays and composite types containing sortable data types.
22136 <entry role=
"func_table_entry"><para role=
"func_signature">
22138 <primary>min
</primary>
22140 <function>min
</function> (
<replaceable>see text
</replaceable> )
22141 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
22144 Computes the minimum of the non-null input
22145 values. Available for any numeric, string, date/time, or enum type,
22146 as well as
<type>inet
</type>,
<type>interval
</type>,
22147 <type>money
</type>,
<type>oid
</type>,
<type>pg_lsn
</type>,
22148 <type>tid
</type>,
<type>xid8
</type>,
22149 and also arrays and composite types containing sortable data types.
22155 <entry role=
"func_table_entry"><para role=
"func_signature">
22157 <primary>range_agg
</primary>
22159 <function>range_agg
</function> (
<parameter>value
</parameter>
22160 <type>anyrange
</type> )
22161 <returnvalue>anymultirange
</returnvalue>
22163 <para role=
"func_signature">
22164 <function>range_agg
</function> (
<parameter>value
</parameter>
22165 <type>anymultirange
</type> )
22166 <returnvalue>anymultirange
</returnvalue>
22169 Computes the union of the non-null input values.
22175 <entry role=
"func_table_entry"><para role=
"func_signature">
22177 <primary>range_intersect_agg
</primary>
22179 <function>range_intersect_agg
</function> (
<parameter>value
</parameter>
22180 <type>anyrange
</type> )
22181 <returnvalue>anyrange
</returnvalue>
22183 <para role=
"func_signature">
22184 <function>range_intersect_agg
</function> (
<parameter>value
</parameter>
22185 <type>anymultirange
</type> )
22186 <returnvalue>anymultirange
</returnvalue>
22189 Computes the intersection of the non-null input values.
22195 <entry role=
"func_table_entry"><para role=
"func_signature">
22197 <primary>string_agg
</primary>
22199 <function>string_agg
</function> (
<parameter>value
</parameter>
22200 <type>text
</type>,
<parameter>delimiter
</parameter> <type>text
</type> )
22201 <returnvalue>text
</returnvalue>
22203 <para role=
"func_signature">
22204 <function>string_agg
</function> (
<parameter>value
</parameter>
22205 <type>bytea
</type>,
<parameter>delimiter
</parameter> <type>bytea
</type>
22206 <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22207 <returnvalue>bytea
</returnvalue>
22210 Concatenates the non-null input values into a string. Each value
22211 after the first is preceded by the
22212 corresponding
<parameter>delimiter
</parameter> (if it's not null).
22218 <entry role=
"func_table_entry"><para role=
"func_signature">
22220 <primary>sum
</primary>
22222 <function>sum
</function> (
<type>smallint
</type> )
22223 <returnvalue>bigint
</returnvalue>
22225 <para role=
"func_signature">
22226 <function>sum
</function> (
<type>integer
</type> )
22227 <returnvalue>bigint
</returnvalue>
22229 <para role=
"func_signature">
22230 <function>sum
</function> (
<type>bigint
</type> )
22231 <returnvalue>numeric
</returnvalue>
22233 <para role=
"func_signature">
22234 <function>sum
</function> (
<type>numeric
</type> )
22235 <returnvalue>numeric
</returnvalue>
22237 <para role=
"func_signature">
22238 <function>sum
</function> (
<type>real
</type> )
22239 <returnvalue>real
</returnvalue>
22241 <para role=
"func_signature">
22242 <function>sum
</function> (
<type>double precision
</type> )
22243 <returnvalue>double precision
</returnvalue>
22245 <para role=
"func_signature">
22246 <function>sum
</function> (
<type>interval
</type> )
22247 <returnvalue>interval
</returnvalue>
22249 <para role=
"func_signature">
22250 <function>sum
</function> (
<type>money
</type> )
22251 <returnvalue>money
</returnvalue>
22254 Computes the sum of the non-null input values.
22260 <entry role=
"func_table_entry"><para role=
"func_signature">
22262 <primary>xmlagg
</primary>
22264 <function>xmlagg
</function> (
<type>xml
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22265 <returnvalue>xml
</returnvalue>
22268 Concatenates the non-null XML input values (see
22269 <xref linkend=
"functions-xml-xmlagg"/>).
22278 It should be noted that except for
<function>count
</function>,
22279 these functions return a null value when no rows are selected. In
22280 particular,
<function>sum
</function> of no rows returns null, not
22281 zero as one might expect, and
<function>array_agg
</function>
22282 returns null rather than an empty array when there are no input
22283 rows. The
<function>coalesce
</function> function can be used to
22284 substitute zero or an empty array for null when necessary.
22288 The aggregate functions
<function>array_agg
</function>,
22289 <function>json_agg
</function>,
<function>jsonb_agg
</function>,
22290 <function>json_agg_strict
</function>,
<function>jsonb_agg_strict
</function>,
22291 <function>json_object_agg
</function>,
<function>jsonb_object_agg
</function>,
22292 <function>json_object_agg_strict
</function>,
<function>jsonb_object_agg_strict
</function>,
22293 <function>json_object_agg_unique
</function>,
<function>jsonb_object_agg_unique
</function>,
22294 <function>json_object_agg_unique_strict
</function>,
22295 <function>jsonb_object_agg_unique_strict
</function>,
22296 <function>string_agg
</function>,
22297 and
<function>xmlagg
</function>, as well as similar user-defined
22298 aggregate functions, produce meaningfully different result values
22299 depending on the order of the input values. This ordering is
22300 unspecified by default, but can be controlled by writing an
22301 <literal>ORDER BY
</literal> clause within the aggregate call, as shown in
22302 <xref linkend=
"syntax-aggregates"/>.
22303 Alternatively, supplying the input values from a sorted subquery
22304 will usually work. For example:
22307 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
22310 Beware that this approach can fail if the outer query level contains
22311 additional processing, such as a join, because that might cause the
22312 subquery's output to be reordered before the aggregate is computed.
22317 <primary>ANY
</primary>
22320 <primary>SOME
</primary>
22323 The boolean aggregates
<function>bool_and
</function> and
22324 <function>bool_or
</function> correspond to the standard SQL aggregates
22325 <function>every
</function> and
<function>any
</function> or
22326 <function>some
</function>.
22327 <productname>PostgreSQL
</productname>
22328 supports
<function>every
</function>, but not
<function>any
</function>
22329 or
<function>some
</function>, because there is an ambiguity built into
22330 the standard syntax:
22332 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
22334 Here
<function>ANY
</function> can be considered either as introducing
22335 a subquery, or as being an aggregate function, if the subquery
22336 returns one row with a Boolean value.
22337 Thus the standard name cannot be given to these aggregates.
22343 Users accustomed to working with other SQL database management
22344 systems might be disappointed by the performance of the
22345 <function>count
</function> aggregate when it is applied to the
22346 entire table. A query like:
22348 SELECT count(*) FROM sometable;
22350 will require effort proportional to the size of the table:
22351 <productname>PostgreSQL
</productname> will need to scan either the
22352 entire table or the entirety of an index that includes all rows in
22358 <xref linkend=
"functions-aggregate-statistics-table"/> shows
22359 aggregate functions typically used in statistical analysis.
22360 (These are separated out merely to avoid cluttering the listing
22361 of more-commonly-used aggregates.) Functions shown as
22362 accepting
<replaceable>numeric_type
</replaceable> are available for all
22363 the types
<type>smallint
</type>,
<type>integer
</type>,
22364 <type>bigint
</type>,
<type>numeric
</type>,
<type>real
</type>,
22365 and
<type>double precision
</type>.
22366 Where the description mentions
22367 <parameter>N
</parameter>, it means the
22368 number of input rows for which all the input expressions are non-null.
22369 In all cases, null is returned if the computation is meaningless,
22370 for example when
<parameter>N
</parameter> is zero.
22374 <primary>statistics
</primary>
22377 <primary>linear regression
</primary>
22380 <table id=
"functions-aggregate-statistics-table">
22381 <title>Aggregate Functions for Statistics
</title>
22383 <colspec colname=
"col1" colwidth=
"10*"/>
22384 <colspec colname=
"col2" colwidth=
"1*"/>
22387 <entry role=
"func_table_entry"><para role=
"func_signature">
22393 <entry>Partial Mode
</entry>
22399 <entry role=
"func_table_entry"><para role=
"func_signature">
22401 <primary>correlation
</primary>
22404 <primary>corr
</primary>
22406 <function>corr
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22407 <returnvalue>double precision
</returnvalue>
22410 Computes the correlation coefficient.
22416 <entry role=
"func_table_entry"><para role=
"func_signature">
22418 <primary>covariance
</primary>
22419 <secondary>population
</secondary>
22422 <primary>covar_pop
</primary>
22424 <function>covar_pop
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22425 <returnvalue>double precision
</returnvalue>
22428 Computes the population covariance.
22434 <entry role=
"func_table_entry"><para role=
"func_signature">
22436 <primary>covariance
</primary>
22437 <secondary>sample
</secondary>
22440 <primary>covar_samp
</primary>
22442 <function>covar_samp
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22443 <returnvalue>double precision
</returnvalue>
22446 Computes the sample covariance.
22452 <entry role=
"func_table_entry"><para role=
"func_signature">
22454 <primary>regr_avgx
</primary>
22456 <function>regr_avgx
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22457 <returnvalue>double precision
</returnvalue>
22460 Computes the average of the independent variable,
22461 <literal>sum(
<parameter>X
</parameter>)/
<parameter>N
</parameter></literal>.
22467 <entry role=
"func_table_entry"><para role=
"func_signature">
22469 <primary>regr_avgy
</primary>
22471 <function>regr_avgy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22472 <returnvalue>double precision
</returnvalue>
22475 Computes the average of the dependent variable,
22476 <literal>sum(
<parameter>Y
</parameter>)/
<parameter>N
</parameter></literal>.
22482 <entry role=
"func_table_entry"><para role=
"func_signature">
22484 <primary>regr_count
</primary>
22486 <function>regr_count
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22487 <returnvalue>bigint
</returnvalue>
22490 Computes the number of rows in which both inputs are non-null.
22496 <entry role=
"func_table_entry"><para role=
"func_signature">
22498 <primary>regression intercept
</primary>
22501 <primary>regr_intercept
</primary>
22503 <function>regr_intercept
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22504 <returnvalue>double precision
</returnvalue>
22507 Computes the y-intercept of the least-squares-fit linear equation
22509 (
<parameter>X
</parameter>,
<parameter>Y
</parameter>) pairs.
22515 <entry role=
"func_table_entry"><para role=
"func_signature">
22517 <primary>regr_r2
</primary>
22519 <function>regr_r2
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22520 <returnvalue>double precision
</returnvalue>
22523 Computes the square of the correlation coefficient.
22529 <entry role=
"func_table_entry"><para role=
"func_signature">
22531 <primary>regression slope
</primary>
22534 <primary>regr_slope
</primary>
22536 <function>regr_slope
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22537 <returnvalue>double precision
</returnvalue>
22540 Computes the slope of the least-squares-fit linear equation determined
22541 by the (
<parameter>X
</parameter>,
<parameter>Y
</parameter>)
22548 <entry role=
"func_table_entry"><para role=
"func_signature">
22550 <primary>regr_sxx
</primary>
22552 <function>regr_sxx
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22553 <returnvalue>double precision
</returnvalue>
22556 Computes the
<quote>sum of squares
</quote> of the independent
22558 <literal>sum(
<parameter>X
</parameter>^
2) - sum(
<parameter>X
</parameter>)^
2/
<parameter>N
</parameter></literal>.
22564 <entry role=
"func_table_entry"><para role=
"func_signature">
22566 <primary>regr_sxy
</primary>
22568 <function>regr_sxy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22569 <returnvalue>double precision
</returnvalue>
22572 Computes the
<quote>sum of products
</quote> of independent times
22573 dependent variables,
22574 <literal>sum(
<parameter>X
</parameter>*
<parameter>Y
</parameter>) - sum(
<parameter>X
</parameter>) * sum(
<parameter>Y
</parameter>)/
<parameter>N
</parameter></literal>.
22580 <entry role=
"func_table_entry"><para role=
"func_signature">
22582 <primary>regr_syy
</primary>
22584 <function>regr_syy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22585 <returnvalue>double precision
</returnvalue>
22588 Computes the
<quote>sum of squares
</quote> of the dependent
22590 <literal>sum(
<parameter>Y
</parameter>^
2) - sum(
<parameter>Y
</parameter>)^
2/
<parameter>N
</parameter></literal>.
22596 <entry role=
"func_table_entry"><para role=
"func_signature">
22598 <primary>standard deviation
</primary>
22601 <primary>stddev
</primary>
22603 <function>stddev
</function> (
<replaceable>numeric_type
</replaceable> )
22604 <returnvalue></returnvalue> <type>double precision
</type>
22605 for
<type>real
</type> or
<type>double precision
</type>,
22606 otherwise
<type>numeric
</type>
22609 This is a historical alias for
<function>stddev_samp
</function>.
22615 <entry role=
"func_table_entry"><para role=
"func_signature">
22617 <primary>standard deviation
</primary>
22618 <secondary>population
</secondary>
22621 <primary>stddev_pop
</primary>
22623 <function>stddev_pop
</function> (
<replaceable>numeric_type
</replaceable> )
22624 <returnvalue></returnvalue> <type>double precision
</type>
22625 for
<type>real
</type> or
<type>double precision
</type>,
22626 otherwise
<type>numeric
</type>
22629 Computes the population standard deviation of the input values.
22635 <entry role=
"func_table_entry"><para role=
"func_signature">
22637 <primary>standard deviation
</primary>
22638 <secondary>sample
</secondary>
22641 <primary>stddev_samp
</primary>
22643 <function>stddev_samp
</function> (
<replaceable>numeric_type
</replaceable> )
22644 <returnvalue></returnvalue> <type>double precision
</type>
22645 for
<type>real
</type> or
<type>double precision
</type>,
22646 otherwise
<type>numeric
</type>
22649 Computes the sample standard deviation of the input values.
22655 <entry role=
"func_table_entry"><para role=
"func_signature">
22657 <primary>variance
</primary>
22659 <function>variance
</function> (
<replaceable>numeric_type
</replaceable> )
22660 <returnvalue></returnvalue> <type>double precision
</type>
22661 for
<type>real
</type> or
<type>double precision
</type>,
22662 otherwise
<type>numeric
</type>
22665 This is a historical alias for
<function>var_samp
</function>.
22671 <entry role=
"func_table_entry"><para role=
"func_signature">
22673 <primary>variance
</primary>
22674 <secondary>population
</secondary>
22677 <primary>var_pop
</primary>
22679 <function>var_pop
</function> (
<replaceable>numeric_type
</replaceable> )
22680 <returnvalue></returnvalue> <type>double precision
</type>
22681 for
<type>real
</type> or
<type>double precision
</type>,
22682 otherwise
<type>numeric
</type>
22685 Computes the population variance of the input values (square of the
22686 population standard deviation).
22692 <entry role=
"func_table_entry"><para role=
"func_signature">
22694 <primary>variance
</primary>
22695 <secondary>sample
</secondary>
22698 <primary>var_samp
</primary>
22700 <function>var_samp
</function> (
<replaceable>numeric_type
</replaceable> )
22701 <returnvalue></returnvalue> <type>double precision
</type>
22702 for
<type>real
</type> or
<type>double precision
</type>,
22703 otherwise
<type>numeric
</type>
22706 Computes the sample variance of the input values (square of the sample
22707 standard deviation).
22716 <xref linkend=
"functions-orderedset-table"/> shows some
22717 aggregate functions that use the
<firstterm>ordered-set aggregate
</firstterm>
22718 syntax. These functions are sometimes referred to as
<quote>inverse
22719 distribution
</quote> functions. Their aggregated input is introduced by
22720 <literal>ORDER BY
</literal>, and they may also take a
<firstterm>direct
22721 argument
</firstterm> that is not aggregated, but is computed only once.
22722 All these functions ignore null values in their aggregated input.
22723 For those that take a
<parameter>fraction
</parameter> parameter, the
22724 fraction value must be between
0 and
1; an error is thrown if not.
22725 However, a null
<parameter>fraction
</parameter> value simply produces a
22730 <primary>ordered-set aggregate
</primary>
22731 <secondary>built-in
</secondary>
22734 <primary>inverse distribution
</primary>
22737 <table id=
"functions-orderedset-table">
22738 <title>Ordered-Set Aggregate Functions
</title>
22740 <colspec colname=
"col1" colwidth=
"10*"/>
22741 <colspec colname=
"col2" colwidth=
"1*"/>
22744 <entry role=
"func_table_entry"><para role=
"func_signature">
22750 <entry>Partial Mode
</entry>
22756 <entry role=
"func_table_entry"><para role=
"func_signature">
22758 <primary>mode
</primary>
22759 <secondary>statistical
</secondary>
22761 <function>mode
</function> ()
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
22762 <returnvalue>anyelement
</returnvalue>
22765 Computes the
<firstterm>mode
</firstterm>, the most frequent
22766 value of the aggregated argument (arbitrarily choosing the first one
22767 if there are multiple equally-frequent values). The aggregated
22768 argument must be of a sortable type.
22774 <entry role=
"func_table_entry"><para role=
"func_signature">
22776 <primary>percentile
</primary>
22777 <secondary>continuous
</secondary>
22779 <function>percentile_cont
</function> (
<parameter>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>double precision
</type> )
22780 <returnvalue>double precision
</returnvalue>
22782 <para role=
"func_signature">
22783 <function>percentile_cont
</function> (
<parameter>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>interval
</type> )
22784 <returnvalue>interval
</returnvalue>
22787 Computes the
<firstterm>continuous percentile
</firstterm>, a value
22788 corresponding to the specified
<parameter>fraction
</parameter>
22789 within the ordered set of aggregated argument values. This will
22790 interpolate between adjacent input items if needed.
22796 <entry role=
"func_table_entry"><para role=
"func_signature">
22797 <function>percentile_cont
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>double precision
</type> )
22798 <returnvalue>double precision[]
</returnvalue>
22800 <para role=
"func_signature">
22801 <function>percentile_cont
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>interval
</type> )
22802 <returnvalue>interval[]
</returnvalue>
22805 Computes multiple continuous percentiles. The result is an array of
22806 the same dimensions as the
<parameter>fractions
</parameter>
22807 parameter, with each non-null element replaced by the (possibly
22808 interpolated) value corresponding to that percentile.
22814 <entry role=
"func_table_entry"><para role=
"func_signature">
22816 <primary>percentile
</primary>
22817 <secondary>discrete
</secondary>
22819 <function>percentile_disc
</function> (
<parameter>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
22820 <returnvalue>anyelement
</returnvalue>
22823 Computes the
<firstterm>discrete percentile
</firstterm>, the first
22824 value within the ordered set of aggregated argument values whose
22825 position in the ordering equals or exceeds the
22826 specified
<parameter>fraction
</parameter>. The aggregated
22827 argument must be of a sortable type.
22833 <entry role=
"func_table_entry"><para role=
"func_signature">
22834 <function>percentile_disc
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
22835 <returnvalue>anyarray
</returnvalue>
22838 Computes multiple discrete percentiles. The result is an array of the
22839 same dimensions as the
<parameter>fractions
</parameter> parameter,
22840 with each non-null element replaced by the input value corresponding
22841 to that percentile.
22842 The aggregated argument must be of a sortable type.
22851 <primary>hypothetical-set aggregate
</primary>
22852 <secondary>built-in
</secondary>
22856 Each of the
<quote>hypothetical-set
</quote> aggregates listed in
22857 <xref linkend=
"functions-hypothetical-table"/> is associated with a
22858 window function of the same name defined in
22859 <xref linkend=
"functions-window"/>. In each case, the aggregate's result
22860 is the value that the associated window function would have
22861 returned for the
<quote>hypothetical
</quote> row constructed from
22862 <replaceable>args
</replaceable>, if such a row had been added to the sorted
22863 group of rows represented by the
<replaceable>sorted_args
</replaceable>.
22864 For each of these functions, the list of direct arguments
22865 given in
<replaceable>args
</replaceable> must match the number and types of
22866 the aggregated arguments given in
<replaceable>sorted_args
</replaceable>.
22867 Unlike most built-in aggregates, these aggregates are not strict, that is
22868 they do not drop input rows containing nulls. Null values sort according
22869 to the rule specified in the
<literal>ORDER BY
</literal> clause.
22872 <table id=
"functions-hypothetical-table">
22873 <title>Hypothetical-Set Aggregate Functions
</title>
22875 <colspec colname=
"col1" colwidth=
"10*"/>
22876 <colspec colname=
"col2" colwidth=
"1*"/>
22879 <entry role=
"func_table_entry"><para role=
"func_signature">
22885 <entry>Partial Mode
</entry>
22891 <entry role=
"func_table_entry"><para role=
"func_signature">
22893 <primary>rank
</primary>
22894 <secondary>hypothetical
</secondary>
22896 <function>rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22897 <returnvalue>bigint
</returnvalue>
22900 Computes the rank of the hypothetical row, with gaps; that is, the row
22901 number of the first row in its peer group.
22907 <entry role=
"func_table_entry"><para role=
"func_signature">
22909 <primary>dense_rank
</primary>
22910 <secondary>hypothetical
</secondary>
22912 <function>dense_rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22913 <returnvalue>bigint
</returnvalue>
22916 Computes the rank of the hypothetical row, without gaps; this function
22917 effectively counts peer groups.
22923 <entry role=
"func_table_entry"><para role=
"func_signature">
22925 <primary>percent_rank
</primary>
22926 <secondary>hypothetical
</secondary>
22928 <function>percent_rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22929 <returnvalue>double precision
</returnvalue>
22932 Computes the relative rank of the hypothetical row, that is
22933 (
<function>rank
</function> -
1) / (total rows -
1).
22934 The value thus ranges from
0 to
1 inclusive.
22940 <entry role=
"func_table_entry"><para role=
"func_signature">
22942 <primary>cume_dist
</primary>
22943 <secondary>hypothetical
</secondary>
22945 <function>cume_dist
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22946 <returnvalue>double precision
</returnvalue>
22949 Computes the cumulative distribution, that is (number of rows
22950 preceding or peers with hypothetical row) / (total rows). The value
22951 thus ranges from
1/
<parameter>N
</parameter> to
1.
22959 <table id=
"functions-grouping-table">
22960 <title>Grouping Operations
</title>
22964 <entry role=
"func_table_entry"><para role=
"func_signature">
22975 <entry role=
"func_table_entry"><para role=
"func_signature">
22977 <primary>GROUPING
</primary>
22979 <function>GROUPING
</function> (
<replaceable>group_by_expression(s)
</replaceable> )
22980 <returnvalue>integer
</returnvalue>
22983 Returns a bit mask indicating which
<literal>GROUP BY
</literal>
22984 expressions are not included in the current grouping set.
22985 Bits are assigned with the rightmost argument corresponding to the
22986 least-significant bit; each bit is
0 if the corresponding expression
22987 is included in the grouping criteria of the grouping set generating
22988 the current result row, and
1 if it is not included.
22996 The grouping operations shown in
22997 <xref linkend=
"functions-grouping-table"/> are used in conjunction with
22998 grouping sets (see
<xref linkend=
"queries-grouping-sets"/>) to distinguish
22999 result rows. The arguments to the
<literal>GROUPING
</literal> function
23000 are not actually evaluated, but they must exactly match expressions given
23001 in the
<literal>GROUP BY
</literal> clause of the associated query level.
23004 <prompt>=
></prompt> <userinput>SELECT * FROM items_sold;
</userinput>
23005 make | model | sales
23006 -------+-------+-------
23013 <prompt>=
></prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);
</userinput>
23014 make | model | grouping | sum
23015 -------+-------+----------+-----
23017 Foo | Tour |
0 |
20
23018 Bar | City |
0 |
15
23019 Bar | Sport |
0 |
5
23025 Here, the
<literal>grouping
</literal> value
<literal>0</literal> in the
23026 first four rows shows that those have been grouped normally, over both the
23027 grouping columns. The value
<literal>1</literal> indicates
23028 that
<literal>model
</literal> was not grouped by in the next-to-last two
23029 rows, and the value
<literal>3</literal> indicates that
23030 neither
<literal>make
</literal> nor
<literal>model
</literal> was grouped
23031 by in the last row (which therefore is an aggregate over all the input
23037 <sect1 id=
"functions-window">
23038 <title>Window Functions
</title>
23040 <indexterm zone=
"functions-window">
23041 <primary>window function
</primary>
23042 <secondary>built-in
</secondary>
23046 <firstterm>Window functions
</firstterm> provide the ability to perform
23047 calculations across sets of rows that are related to the current query
23048 row. See
<xref linkend=
"tutorial-window"/> for an introduction to this
23049 feature, and
<xref linkend=
"syntax-window-functions"/> for syntax
23054 The built-in window functions are listed in
23055 <xref linkend=
"functions-window-table"/>. Note that these functions
23056 <emphasis>must
</emphasis> be invoked using window function syntax, i.e., an
23057 <literal>OVER
</literal> clause is required.
23061 In addition to these functions, any built-in or user-defined
23062 ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates)
23063 can be used as a window function; see
23064 <xref linkend=
"functions-aggregate"/> for a list of the built-in aggregates.
23065 Aggregate functions act as window functions only when an
<literal>OVER
</literal>
23066 clause follows the call; otherwise they act as plain aggregates
23067 and return a single row for the entire set.
23070 <table id=
"functions-window-table">
23071 <title>General-Purpose Window Functions
</title>
23075 <entry role=
"func_table_entry"><para role=
"func_signature">
23086 <entry role=
"func_table_entry"><para role=
"func_signature">
23088 <primary>row_number
</primary>
23090 <function>row_number
</function> ()
23091 <returnvalue>bigint
</returnvalue>
23094 Returns the number of the current row within its partition, counting
23100 <entry role=
"func_table_entry"><para role=
"func_signature">
23102 <primary>rank
</primary>
23104 <function>rank
</function> ()
23105 <returnvalue>bigint
</returnvalue>
23108 Returns the rank of the current row, with gaps; that is,
23109 the
<function>row_number
</function> of the first row in its peer
23115 <entry role=
"func_table_entry"><para role=
"func_signature">
23117 <primary>dense_rank
</primary>
23119 <function>dense_rank
</function> ()
23120 <returnvalue>bigint
</returnvalue>
23123 Returns the rank of the current row, without gaps; this function
23124 effectively counts peer groups.
23129 <entry role=
"func_table_entry"><para role=
"func_signature">
23131 <primary>percent_rank
</primary>
23133 <function>percent_rank
</function> ()
23134 <returnvalue>double precision
</returnvalue>
23137 Returns the relative rank of the current row, that is
23138 (
<function>rank
</function> -
1) / (total partition rows -
1).
23139 The value thus ranges from
0 to
1 inclusive.
23144 <entry role=
"func_table_entry"><para role=
"func_signature">
23146 <primary>cume_dist
</primary>
23148 <function>cume_dist
</function> ()
23149 <returnvalue>double precision
</returnvalue>
23152 Returns the cumulative distribution, that is (number of partition rows
23153 preceding or peers with current row) / (total partition rows).
23154 The value thus ranges from
1/
<parameter>N
</parameter> to
1.
23159 <entry role=
"func_table_entry"><para role=
"func_signature">
23161 <primary>ntile
</primary>
23163 <function>ntile
</function> (
<parameter>num_buckets
</parameter> <type>integer
</type> )
23164 <returnvalue>integer
</returnvalue>
23167 Returns an integer ranging from
1 to the argument value, dividing the
23168 partition as equally as possible.
23173 <entry role=
"func_table_entry"><para role=
"func_signature">
23175 <primary>lag
</primary>
23177 <function>lag
</function> (
<parameter>value
</parameter> <type>anycompatible
</type>
23178 <optional>,
<parameter>offset
</parameter> <type>integer
</type>
23179 <optional>,
<parameter>default
</parameter> <type>anycompatible
</type> </optional></optional> )
23180 <returnvalue>anycompatible
</returnvalue>
23183 Returns
<parameter>value
</parameter> evaluated at
23184 the row that is
<parameter>offset
</parameter>
23185 rows before the current row within the partition; if there is no such
23186 row, instead returns
<parameter>default
</parameter>
23187 (which must be of a type compatible with
23188 <parameter>value
</parameter>).
23189 Both
<parameter>offset
</parameter> and
23190 <parameter>default
</parameter> are evaluated
23191 with respect to the current row. If omitted,
23192 <parameter>offset
</parameter> defaults to
1 and
23193 <parameter>default
</parameter> to
<literal>NULL
</literal>.
23198 <entry role=
"func_table_entry"><para role=
"func_signature">
23200 <primary>lead
</primary>
23202 <function>lead
</function> (
<parameter>value
</parameter> <type>anycompatible
</type>
23203 <optional>,
<parameter>offset
</parameter> <type>integer
</type>
23204 <optional>,
<parameter>default
</parameter> <type>anycompatible
</type> </optional></optional> )
23205 <returnvalue>anycompatible
</returnvalue>
23208 Returns
<parameter>value
</parameter> evaluated at
23209 the row that is
<parameter>offset
</parameter>
23210 rows after the current row within the partition; if there is no such
23211 row, instead returns
<parameter>default
</parameter>
23212 (which must be of a type compatible with
23213 <parameter>value
</parameter>).
23214 Both
<parameter>offset
</parameter> and
23215 <parameter>default
</parameter> are evaluated
23216 with respect to the current row. If omitted,
23217 <parameter>offset
</parameter> defaults to
1 and
23218 <parameter>default
</parameter> to
<literal>NULL
</literal>.
23223 <entry role=
"func_table_entry"><para role=
"func_signature">
23225 <primary>first_value
</primary>
23227 <function>first_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type> )
23228 <returnvalue>anyelement
</returnvalue>
23231 Returns
<parameter>value
</parameter> evaluated
23232 at the row that is the first row of the window frame.
23237 <entry role=
"func_table_entry"><para role=
"func_signature">
23239 <primary>last_value
</primary>
23241 <function>last_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type> )
23242 <returnvalue>anyelement
</returnvalue>
23245 Returns
<parameter>value
</parameter> evaluated
23246 at the row that is the last row of the window frame.
23251 <entry role=
"func_table_entry"><para role=
"func_signature">
23253 <primary>nth_value
</primary>
23255 <function>nth_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type>,
<parameter>n
</parameter> <type>integer
</type> )
23256 <returnvalue>anyelement
</returnvalue>
23259 Returns
<parameter>value
</parameter> evaluated
23260 at the row that is the
<parameter>n
</parameter>'th
23261 row of the window frame (counting from
1);
23262 returns
<literal>NULL
</literal> if there is no such row.
23270 All of the functions listed in
23271 <xref linkend=
"functions-window-table"/> depend on the sort ordering
23272 specified by the
<literal>ORDER BY
</literal> clause of the associated window
23273 definition. Rows that are not distinct when considering only the
23274 <literal>ORDER BY
</literal> columns are said to be
<firstterm>peers
</firstterm>.
23275 The four ranking functions (including
<function>cume_dist
</function>) are
23276 defined so that they give the same answer for all rows of a peer group.
23280 Note that
<function>first_value
</function>,
<function>last_value
</function>, and
23281 <function>nth_value
</function> consider only the rows within the
<quote>window
23282 frame
</quote>, which by default contains the rows from the start of the
23283 partition through the last peer of the current row. This is
23284 likely to give unhelpful results for
<function>last_value
</function> and
23285 sometimes also
<function>nth_value
</function>. You can redefine the frame by
23286 adding a suitable frame specification (
<literal>RANGE
</literal>,
23287 <literal>ROWS
</literal> or
<literal>GROUPS
</literal>) to
23288 the
<literal>OVER
</literal> clause.
23289 See
<xref linkend=
"syntax-window-functions"/> for more information
23290 about frame specifications.
23294 When an aggregate function is used as a window function, it aggregates
23295 over the rows within the current row's window frame.
23296 An aggregate used with
<literal>ORDER BY
</literal> and the default window frame
23297 definition produces a
<quote>running sum
</quote> type of behavior, which may or
23298 may not be what's wanted. To obtain
23299 aggregation over the whole partition, omit
<literal>ORDER BY
</literal> or use
23300 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
</literal>.
23301 Other frame specifications can be used to obtain other effects.
23306 The SQL standard defines a
<literal>RESPECT NULLS
</literal> or
23307 <literal>IGNORE NULLS
</literal> option for
<function>lead
</function>,
<function>lag
</function>,
23308 <function>first_value
</function>,
<function>last_value
</function>, and
23309 <function>nth_value
</function>. This is not implemented in
23310 <productname>PostgreSQL
</productname>: the behavior is always the
23311 same as the standard's default, namely
<literal>RESPECT NULLS
</literal>.
23312 Likewise, the standard's
<literal>FROM FIRST
</literal> or
<literal>FROM LAST
</literal>
23313 option for
<function>nth_value
</function> is not implemented: only the
23314 default
<literal>FROM FIRST
</literal> behavior is supported. (You can achieve
23315 the result of
<literal>FROM LAST
</literal> by reversing the
<literal>ORDER BY
</literal>
23322 <sect1 id=
"functions-merge-support">
23323 <title>Merge Support Functions
</title>
23326 <primary>MERGE
</primary>
23327 <secondary>RETURNING
</secondary>
23331 <productname>PostgreSQL
</productname> includes one merge support function
23332 that may be used in the
<literal>RETURNING
</literal> list of a
23333 <xref linkend=
"sql-merge"/> command to identify the action taken for each
23334 row; see
<xref linkend=
"functions-merge-support-table"/>.
23337 <table id=
"functions-merge-support-table">
23338 <title>Merge Support Functions
</title>
23343 <entry role=
"func_table_entry"><para role=
"func_signature">
23354 <entry id=
"merge-action" role=
"func_table_entry"><para role=
"func_signature">
23356 <primary>merge_action
</primary>
23358 <function>merge_action
</function> ( )
23359 <returnvalue>text
</returnvalue>
23362 Returns the merge action command executed for the current row. This
23363 will be
<literal>'INSERT'
</literal>,
<literal>'UPDATE'
</literal>, or
23364 <literal>'DELETE'
</literal>.
23374 MERGE INTO products p
23375 USING stock s ON p.product_id = s.product_id
23376 WHEN MATCHED AND s.quantity
> 0 THEN
23377 UPDATE SET in_stock = true, quantity = s.quantity
23379 UPDATE SET in_stock = false, quantity =
0
23380 WHEN NOT MATCHED THEN
23381 INSERT (product_id, in_stock, quantity)
23382 VALUES (s.product_id, true, s.quantity)
23383 RETURNING merge_action(), p.*;
23385 merge_action | product_id | in_stock | quantity
23386 --------------+------------+----------+----------
23387 UPDATE |
1001 | t |
50
23388 UPDATE |
1002 | f |
0
23389 INSERT |
1003 | t |
10
23394 Note that this function can only be used in the
<literal>RETURNING
</literal>
23395 list of a
<command>MERGE
</command> command. It is an error to use it in any
23396 other part of a query.
23401 <sect1 id=
"functions-subquery">
23402 <title>Subquery Expressions
</title>
23405 <primary>EXISTS
</primary>
23409 <primary>IN
</primary>
23413 <primary>NOT IN
</primary>
23417 <primary>ANY
</primary>
23421 <primary>ALL
</primary>
23425 <primary>SOME
</primary>
23429 <primary>subquery
</primary>
23433 This section describes the
<acronym>SQL
</acronym>-compliant subquery
23434 expressions available in
<productname>PostgreSQL
</productname>.
23435 All of the expression forms documented in this section return
23436 Boolean (true/false) results.
23439 <sect2 id=
"functions-subquery-exists">
23440 <title><literal>EXISTS
</literal></title>
23443 EXISTS (
<replaceable>subquery
</replaceable>)
23447 The argument of
<token>EXISTS
</token> is an arbitrary
<command>SELECT
</command> statement,
23448 or
<firstterm>subquery
</firstterm>. The
23449 subquery is evaluated to determine whether it returns any rows.
23450 If it returns at least one row, the result of
<token>EXISTS
</token> is
23451 <quote>true
</quote>; if the subquery returns no rows, the result of
<token>EXISTS
</token>
23452 is
<quote>false
</quote>.
23456 The subquery can refer to variables from the surrounding query,
23457 which will act as constants during any one evaluation of the subquery.
23461 The subquery will generally only be executed long enough to determine
23462 whether at least one row is returned, not all the way to completion.
23463 It is unwise to write a subquery that has side effects (such as
23464 calling sequence functions); whether the side effects occur
23465 might be unpredictable.
23469 Since the result depends only on whether any rows are returned,
23470 and not on the contents of those rows, the output list of the
23471 subquery is normally unimportant. A common coding convention is
23472 to write all
<literal>EXISTS
</literal> tests in the form
23473 <literal>EXISTS(SELECT
1 WHERE ...)
</literal>. There are exceptions to
23474 this rule however, such as subqueries that use
<token>INTERSECT
</token>.
23478 This simple example is like an inner join on
<literal>col2
</literal>, but
23479 it produces at most one output row for each
<literal>tab1
</literal> row,
23480 even if there are several matching
<literal>tab2
</literal> rows:
23484 WHERE EXISTS (SELECT
1 FROM tab2 WHERE col2 = tab1.col2);
23489 <sect2 id=
"functions-subquery-in">
23490 <title><literal>IN
</literal></title>
23493 <replaceable>expression
</replaceable> IN (
<replaceable>subquery
</replaceable>)
23497 The right-hand side is a parenthesized
23498 subquery, which must return exactly one column. The left-hand expression
23499 is evaluated and compared to each row of the subquery result.
23500 The result of
<token>IN
</token> is
<quote>true
</quote> if any equal subquery row is found.
23501 The result is
<quote>false
</quote> if no equal row is found (including the
23502 case where the subquery returns no rows).
23506 Note that if the left-hand expression yields null, or if there are
23507 no equal right-hand values and at least one right-hand row yields
23508 null, the result of the
<token>IN
</token> construct will be null, not false.
23509 This is in accordance with SQL's normal rules for Boolean combinations
23514 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23515 be evaluated completely.
23519 <replaceable>row_constructor
</replaceable> IN (
<replaceable>subquery
</replaceable>)
23523 The left-hand side of this form of
<token>IN
</token> is a row constructor,
23524 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23525 The right-hand side is a parenthesized
23526 subquery, which must return exactly as many columns as there are
23527 expressions in the left-hand row. The left-hand expressions are
23528 evaluated and compared row-wise to each row of the subquery result.
23529 The result of
<token>IN
</token> is
<quote>true
</quote> if any equal subquery row is found.
23530 The result is
<quote>false
</quote> if no equal row is found (including the
23531 case where the subquery returns no rows).
23535 As usual, null values in the rows are combined per
23536 the normal rules of SQL Boolean expressions. Two rows are considered
23537 equal if all their corresponding members are non-null and equal; the rows
23538 are unequal if any corresponding members are non-null and unequal;
23539 otherwise the result of that row comparison is unknown (null).
23540 If all the per-row results are either unequal or null, with at least one
23541 null, then the result of
<token>IN
</token> is null.
23545 <sect2 id=
"functions-subquery-notin">
23546 <title><literal>NOT IN
</literal></title>
23549 <replaceable>expression
</replaceable> NOT IN (
<replaceable>subquery
</replaceable>)
23553 The right-hand side is a parenthesized
23554 subquery, which must return exactly one column. The left-hand expression
23555 is evaluated and compared to each row of the subquery result.
23556 The result of
<token>NOT IN
</token> is
<quote>true
</quote> if only unequal subquery rows
23557 are found (including the case where the subquery returns no rows).
23558 The result is
<quote>false
</quote> if any equal row is found.
23562 Note that if the left-hand expression yields null, or if there are
23563 no equal right-hand values and at least one right-hand row yields
23564 null, the result of the
<token>NOT IN
</token> construct will be null, not true.
23565 This is in accordance with SQL's normal rules for Boolean combinations
23570 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23571 be evaluated completely.
23575 <replaceable>row_constructor
</replaceable> NOT IN (
<replaceable>subquery
</replaceable>)
23579 The left-hand side of this form of
<token>NOT IN
</token> is a row constructor,
23580 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23581 The right-hand side is a parenthesized
23582 subquery, which must return exactly as many columns as there are
23583 expressions in the left-hand row. The left-hand expressions are
23584 evaluated and compared row-wise to each row of the subquery result.
23585 The result of
<token>NOT IN
</token> is
<quote>true
</quote> if only unequal subquery rows
23586 are found (including the case where the subquery returns no rows).
23587 The result is
<quote>false
</quote> if any equal row is found.
23591 As usual, null values in the rows are combined per
23592 the normal rules of SQL Boolean expressions. Two rows are considered
23593 equal if all their corresponding members are non-null and equal; the rows
23594 are unequal if any corresponding members are non-null and unequal;
23595 otherwise the result of that row comparison is unknown (null).
23596 If all the per-row results are either unequal or null, with at least one
23597 null, then the result of
<token>NOT IN
</token> is null.
23601 <sect2 id=
"functions-subquery-any-some">
23602 <title><literal>ANY
</literal>/
<literal>SOME
</literal></title>
23605 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>subquery
</replaceable>)
23606 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>subquery
</replaceable>)
23610 The right-hand side is a parenthesized
23611 subquery, which must return exactly one column. The left-hand expression
23612 is evaluated and compared to each row of the subquery result using the
23613 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23615 The result of
<token>ANY
</token> is
<quote>true
</quote> if any true result is obtained.
23616 The result is
<quote>false
</quote> if no true result is found (including the
23617 case where the subquery returns no rows).
23621 <token>SOME
</token> is a synonym for
<token>ANY
</token>.
23622 <token>IN
</token> is equivalent to
<literal>= ANY
</literal>.
23626 Note that if there are no successes and at least one right-hand row yields
23627 null for the operator's result, the result of the
<token>ANY
</token> construct
23628 will be null, not false.
23629 This is in accordance with SQL's normal rules for Boolean combinations
23634 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23635 be evaluated completely.
23639 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>subquery
</replaceable>)
23640 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>subquery
</replaceable>)
23644 The left-hand side of this form of
<token>ANY
</token> is a row constructor,
23645 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23646 The right-hand side is a parenthesized
23647 subquery, which must return exactly as many columns as there are
23648 expressions in the left-hand row. The left-hand expressions are
23649 evaluated and compared row-wise to each row of the subquery result,
23650 using the given
<replaceable>operator
</replaceable>.
23651 The result of
<token>ANY
</token> is
<quote>true
</quote> if the comparison
23652 returns true for any subquery row.
23653 The result is
<quote>false
</quote> if the comparison returns false for every
23654 subquery row (including the case where the subquery returns no
23656 The result is NULL if no comparison with a subquery row returns true,
23657 and at least one comparison returns NULL.
23661 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
23662 of a row constructor comparison.
23666 <sect2 id=
"functions-subquery-all">
23667 <title><literal>ALL
</literal></title>
23670 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>subquery
</replaceable>)
23674 The right-hand side is a parenthesized
23675 subquery, which must return exactly one column. The left-hand expression
23676 is evaluated and compared to each row of the subquery result using the
23677 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23679 The result of
<token>ALL
</token> is
<quote>true
</quote> if all rows yield true
23680 (including the case where the subquery returns no rows).
23681 The result is
<quote>false
</quote> if any false result is found.
23682 The result is NULL if no comparison with a subquery row returns false,
23683 and at least one comparison returns NULL.
23687 <token>NOT IN
</token> is equivalent to
<literal><> ALL
</literal>.
23691 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23692 be evaluated completely.
23696 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>subquery
</replaceable>)
23700 The left-hand side of this form of
<token>ALL
</token> is a row constructor,
23701 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23702 The right-hand side is a parenthesized
23703 subquery, which must return exactly as many columns as there are
23704 expressions in the left-hand row. The left-hand expressions are
23705 evaluated and compared row-wise to each row of the subquery result,
23706 using the given
<replaceable>operator
</replaceable>.
23707 The result of
<token>ALL
</token> is
<quote>true
</quote> if the comparison
23708 returns true for all subquery rows (including the
23709 case where the subquery returns no rows).
23710 The result is
<quote>false
</quote> if the comparison returns false for any
23712 The result is NULL if no comparison with a subquery row returns false,
23713 and at least one comparison returns NULL.
23717 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
23718 of a row constructor comparison.
23722 <sect2 id=
"functions-subquery-single-row-comp">
23723 <title>Single-Row Comparison
</title>
23725 <indexterm zone=
"functions-subquery">
23726 <primary>comparison
</primary>
23727 <secondary>subquery result row
</secondary>
23731 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> (
<replaceable>subquery
</replaceable>)
23735 The left-hand side is a row constructor,
23736 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23737 The right-hand side is a parenthesized subquery, which must return exactly
23738 as many columns as there are expressions in the left-hand row. Furthermore,
23739 the subquery cannot return more than one row. (If it returns zero rows,
23740 the result is taken to be null.) The left-hand side is evaluated and
23741 compared row-wise to the single subquery result row.
23745 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
23746 of a row constructor comparison.
23752 <sect1 id=
"functions-comparisons">
23753 <title>Row and Array Comparisons
</title>
23756 <primary>IN
</primary>
23760 <primary>NOT IN
</primary>
23764 <primary>ANY
</primary>
23768 <primary>ALL
</primary>
23772 <primary>SOME
</primary>
23776 <primary>composite type
</primary>
23777 <secondary>comparison
</secondary>
23781 <primary>row-wise comparison
</primary>
23785 <primary>comparison
</primary>
23786 <secondary>composite type
</secondary>
23790 <primary>comparison
</primary>
23791 <secondary>row constructor
</secondary>
23795 <primary>IS DISTINCT FROM
</primary>
23799 <primary>IS NOT DISTINCT FROM
</primary>
23803 This section describes several specialized constructs for making
23804 multiple comparisons between groups of values. These forms are
23805 syntactically related to the subquery forms of the previous section,
23806 but do not involve subqueries.
23807 The forms involving array subexpressions are
23808 <productname>PostgreSQL
</productname> extensions; the rest are
23809 <acronym>SQL
</acronym>-compliant.
23810 All of the expression forms documented in this section return
23811 Boolean (true/false) results.
23814 <sect2 id=
"functions-comparisons-in-scalar">
23815 <title><literal>IN
</literal></title>
23818 <replaceable>expression
</replaceable> IN (
<replaceable>value
</replaceable> <optional>, ...
</optional>)
23822 The right-hand side is a parenthesized list
23823 of expressions. The result is
<quote>true
</quote> if the left-hand expression's
23824 result is equal to any of the right-hand expressions. This is a shorthand
23828 <replaceable>expression
</replaceable> =
<replaceable>value1
</replaceable>
23830 <replaceable>expression
</replaceable> =
<replaceable>value2
</replaceable>
23837 Note that if the left-hand expression yields null, or if there are
23838 no equal right-hand values and at least one right-hand expression yields
23839 null, the result of the
<token>IN
</token> construct will be null, not false.
23840 This is in accordance with SQL's normal rules for Boolean combinations
23845 <sect2 id=
"functions-comparisons-not-in">
23846 <title><literal>NOT IN
</literal></title>
23849 <replaceable>expression
</replaceable> NOT IN (
<replaceable>value
</replaceable> <optional>, ...
</optional>)
23853 The right-hand side is a parenthesized list
23854 of expressions. The result is
<quote>true
</quote> if the left-hand expression's
23855 result is unequal to all of the right-hand expressions. This is a shorthand
23859 <replaceable>expression
</replaceable> <> <replaceable>value1
</replaceable>
23861 <replaceable>expression
</replaceable> <> <replaceable>value2
</replaceable>
23868 Note that if the left-hand expression yields null, or if there are
23869 no equal right-hand values and at least one right-hand expression yields
23870 null, the result of the
<token>NOT IN
</token> construct will be null, not true
23871 as one might naively expect.
23872 This is in accordance with SQL's normal rules for Boolean combinations
23878 <literal>x NOT IN y
</literal> is equivalent to
<literal>NOT (x IN y)
</literal> in all
23879 cases. However, null values are much more likely to trip up the novice when
23880 working with
<token>NOT IN
</token> than when working with
<token>IN
</token>.
23881 It is best to express your condition positively if possible.
23886 <sect2 id=
"functions-comparisons-any-some">
23887 <title><literal>ANY
</literal>/
<literal>SOME
</literal> (array)
</title>
23890 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>array expression
</replaceable>)
23891 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>array expression
</replaceable>)
23895 The right-hand side is a parenthesized expression, which must yield an
23897 The left-hand expression
23898 is evaluated and compared to each element of the array using the
23899 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23901 The result of
<token>ANY
</token> is
<quote>true
</quote> if any true result is obtained.
23902 The result is
<quote>false
</quote> if no true result is found (including the
23903 case where the array has zero elements).
23907 If the array expression yields a null array, the result of
23908 <token>ANY
</token> will be null. If the left-hand expression yields null,
23909 the result of
<token>ANY
</token> is ordinarily null (though a non-strict
23910 comparison operator could possibly yield a different result).
23911 Also, if the right-hand array contains any null elements and no true
23912 comparison result is obtained, the result of
<token>ANY
</token>
23913 will be null, not false (again, assuming a strict comparison operator).
23914 This is in accordance with SQL's normal rules for Boolean combinations
23919 <token>SOME
</token> is a synonym for
<token>ANY
</token>.
23923 <sect2 id=
"functions-comparisons-all">
23924 <title><literal>ALL
</literal> (array)
</title>
23927 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>array expression
</replaceable>)
23931 The right-hand side is a parenthesized expression, which must yield an
23933 The left-hand expression
23934 is evaluated and compared to each element of the array using the
23935 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23937 The result of
<token>ALL
</token> is
<quote>true
</quote> if all comparisons yield true
23938 (including the case where the array has zero elements).
23939 The result is
<quote>false
</quote> if any false result is found.
23943 If the array expression yields a null array, the result of
23944 <token>ALL
</token> will be null. If the left-hand expression yields null,
23945 the result of
<token>ALL
</token> is ordinarily null (though a non-strict
23946 comparison operator could possibly yield a different result).
23947 Also, if the right-hand array contains any null elements and no false
23948 comparison result is obtained, the result of
<token>ALL
</token>
23949 will be null, not true (again, assuming a strict comparison operator).
23950 This is in accordance with SQL's normal rules for Boolean combinations
23955 <sect2 id=
"row-wise-comparison">
23956 <title>Row Constructor Comparison
</title>
23959 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> <replaceable>row_constructor
</replaceable>
23963 Each side is a row constructor,
23964 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23965 The two row constructors must have the same number of fields.
23966 The given
<replaceable>operator
</replaceable> is applied to each pair
23967 of corresponding fields. (Since the fields could be of different
23968 types, this means that a different specific operator could be selected
23970 All the selected operators must be members of some B-tree operator
23971 class, or be the negator of an
<literal>=
</literal> member of a B-tree
23972 operator class, meaning that row constructor comparison is only
23973 possible when the
<replaceable>operator
</replaceable> is
23974 <literal>=
</literal>,
23975 <literal><></literal>,
23976 <literal><</literal>,
23977 <literal><=
</literal>,
23978 <literal>></literal>, or
23979 <literal>>=
</literal>,
23980 or has semantics similar to one of these.
23984 The
<literal>=
</literal> and
<literal><></literal> cases work slightly differently
23985 from the others. Two rows are considered
23986 equal if all their corresponding members are non-null and equal; the rows
23987 are unequal if any corresponding members are non-null and unequal;
23988 otherwise the result of the row comparison is unknown (null).
23992 For the
<literal><</literal>,
<literal><=
</literal>,
<literal>></literal> and
23993 <literal>>=
</literal> cases, the row elements are compared left-to-right,
23994 stopping as soon as an unequal or null pair of elements is found.
23995 If either of this pair of elements is null, the result of the
23996 row comparison is unknown (null); otherwise comparison of this pair
23997 of elements determines the result. For example,
23998 <literal>ROW(
1,
2,NULL)
< ROW(
1,
3,
0)
</literal>
23999 yields true, not null, because the third pair of elements are not
24004 <replaceable>row_constructor
</replaceable> IS DISTINCT FROM
<replaceable>row_constructor
</replaceable>
24008 This construct is similar to a
<literal><></literal> row comparison,
24009 but it does not yield null for null inputs. Instead, any null value is
24010 considered unequal to (distinct from) any non-null value, and any two
24011 nulls are considered equal (not distinct). Thus the result will
24012 either be true or false, never null.
24016 <replaceable>row_constructor
</replaceable> IS NOT DISTINCT FROM
<replaceable>row_constructor
</replaceable>
24020 This construct is similar to a
<literal>=
</literal> row comparison,
24021 but it does not yield null for null inputs. Instead, any null value is
24022 considered unequal to (distinct from) any non-null value, and any two
24023 nulls are considered equal (not distinct). Thus the result will always
24024 be either true or false, never null.
24029 <sect2 id=
"composite-type-comparison">
24030 <title>Composite Type Comparison
</title>
24033 <replaceable>record
</replaceable> <replaceable>operator
</replaceable> <replaceable>record
</replaceable>
24037 The SQL specification requires row-wise comparison to return NULL if the
24038 result depends on comparing two NULL values or a NULL and a non-NULL.
24039 <productname>PostgreSQL
</productname> does this only when comparing the
24040 results of two row constructors (as in
24041 <xref linkend=
"row-wise-comparison"/>) or comparing a row constructor
24042 to the output of a subquery (as in
<xref linkend=
"functions-subquery"/>).
24043 In other contexts where two composite-type values are compared, two
24044 NULL field values are considered equal, and a NULL is considered larger
24045 than a non-NULL. This is necessary in order to have consistent sorting
24046 and indexing behavior for composite types.
24050 Each side is evaluated and they are compared row-wise. Composite type
24051 comparisons are allowed when the
<replaceable>operator
</replaceable> is
24052 <literal>=
</literal>,
24053 <literal><></literal>,
24054 <literal><</literal>,
24055 <literal><=
</literal>,
24056 <literal>></literal> or
24057 <literal>>=
</literal>,
24058 or has semantics similar to one of these. (To be specific, an operator
24059 can be a row comparison operator if it is a member of a B-tree operator
24060 class, or is the negator of the
<literal>=
</literal> member of a B-tree operator
24061 class.) The default behavior of the above operators is the same as for
24062 <literal>IS [ NOT ] DISTINCT FROM
</literal> for row constructors (see
24063 <xref linkend=
"row-wise-comparison"/>).
24067 To support matching of rows which include elements without a default
24068 B-tree operator class, the following operators are defined for composite
24070 <literal>*=
</literal>,
24071 <literal>*
<></literal>,
24072 <literal>*
<</literal>,
24073 <literal>*
<=
</literal>,
24074 <literal>*
></literal>, and
24075 <literal>*
>=
</literal>.
24076 These operators compare the internal binary representation of the two
24077 rows. Two rows might have a different binary representation even
24078 though comparisons of the two rows with the equality operator is true.
24079 The ordering of rows under these comparison operators is deterministic
24080 but not otherwise meaningful. These operators are used internally
24081 for materialized views and might be useful for other specialized
24082 purposes such as replication and B-Tree deduplication (see
<xref
24083 linkend=
"btree-deduplication"/>). They are not intended to be
24084 generally useful for writing queries, though.
24089 <sect1 id=
"functions-srf">
24090 <title>Set Returning Functions
</title>
24092 <indexterm zone=
"functions-srf">
24093 <primary>set returning functions
</primary>
24094 <secondary>functions
</secondary>
24098 This section describes functions that possibly return more than one row.
24099 The most widely used functions in this class are series generating
24100 functions, as detailed in
<xref linkend=
"functions-srf-series"/> and
24101 <xref linkend=
"functions-srf-subscripts"/>. Other, more specialized
24102 set-returning functions are described elsewhere in this manual.
24103 See
<xref linkend=
"queries-tablefunctions"/> for ways to combine multiple
24104 set-returning functions.
24107 <table id=
"functions-srf-series">
24108 <title>Series Generating Functions
</title>
24112 <entry role=
"func_table_entry"><para role=
"func_signature">
24123 <entry role=
"func_table_entry"><para role=
"func_signature">
24125 <primary>generate_series
</primary>
24127 <function>generate_series
</function> (
<parameter>start
</parameter> <type>integer
</type>,
<parameter>stop
</parameter> <type>integer
</type> <optional>,
<parameter>step
</parameter> <type>integer
</type> </optional> )
24128 <returnvalue>setof integer
</returnvalue>
24130 <para role=
"func_signature">
24131 <function>generate_series
</function> (
<parameter>start
</parameter> <type>bigint
</type>,
<parameter>stop
</parameter> <type>bigint
</type> <optional>,
<parameter>step
</parameter> <type>bigint
</type> </optional> )
24132 <returnvalue>setof bigint
</returnvalue>
24134 <para role=
"func_signature">
24135 <function>generate_series
</function> (
<parameter>start
</parameter> <type>numeric
</type>,
<parameter>stop
</parameter> <type>numeric
</type> <optional>,
<parameter>step
</parameter> <type>numeric
</type> </optional> )
24136 <returnvalue>setof numeric
</returnvalue>
24139 Generates a series of values from
<parameter>start
</parameter>
24140 to
<parameter>stop
</parameter>, with a step size
24141 of
<parameter>step
</parameter>.
<parameter>step
</parameter>
24147 <entry role=
"func_table_entry"><para role=
"func_signature">
24148 <function>generate_series
</function> (
<parameter>start
</parameter> <type>timestamp
</type>,
<parameter>stop
</parameter> <type>timestamp
</type>,
<parameter>step
</parameter> <type>interval
</type> )
24149 <returnvalue>setof timestamp
</returnvalue>
24151 <para role=
"func_signature">
24152 <function>generate_series
</function> (
<parameter>start
</parameter> <type>timestamp with time zone
</type>,
<parameter>stop
</parameter> <type>timestamp with time zone
</type>,
<parameter>step
</parameter> <type>interval
</type> <optional>,
<parameter>timezone
</parameter> <type>text
</type> </optional> )
24153 <returnvalue>setof timestamp with time zone
</returnvalue>
24156 Generates a series of values from
<parameter>start
</parameter>
24157 to
<parameter>stop
</parameter>, with a step size
24158 of
<parameter>step
</parameter>.
24159 In the timezone-aware form, times of day and daylight-savings
24160 adjustments are computed according to the time zone named by
24161 the
<parameter>timezone
</parameter> argument, or the current
24162 <xref linkend=
"guc-timezone"/> setting if that is omitted.
24170 When
<parameter>step
</parameter> is positive, zero rows are returned if
24171 <parameter>start
</parameter> is greater than
<parameter>stop
</parameter>.
24172 Conversely, when
<parameter>step
</parameter> is negative, zero rows are
24173 returned if
<parameter>start
</parameter> is less than
<parameter>stop
</parameter>.
24174 Zero rows are also returned if any input is
<literal>NULL
</literal>.
24176 for
<parameter>step
</parameter> to be zero. Some examples follow:
24178 SELECT * FROM generate_series(
2,
4);
24186 SELECT * FROM generate_series(
5,
1,-
2);
24194 SELECT * FROM generate_series(
4,
3);
24199 SELECT generate_series(
1.1,
4,
1.3);
24207 -- this example relies on the date-plus-integer operator:
24208 SELECT current_date + s.a AS dates FROM generate_series(
0,
14,
7) AS s(a);
24216 SELECT * FROM generate_series('
2008-
03-
01 00:
00'::timestamp,
24217 '
2008-
03-
04 12:
00', '
10 hours');
24219 ---------------------
24220 2008-
03-
01 00:
00:
00
24221 2008-
03-
01 10:
00:
00
24222 2008-
03-
01 20:
00:
00
24223 2008-
03-
02 06:
00:
00
24224 2008-
03-
02 16:
00:
00
24225 2008-
03-
03 02:
00:
00
24226 2008-
03-
03 12:
00:
00
24227 2008-
03-
03 22:
00:
00
24228 2008-
03-
04 08:
00:
00
24231 -- this example assumes that TimeZone is set to UTC; note the DST transition:
24232 SELECT * FROM generate_series('
2001-
10-
22 00:
00 -
04:
00'::timestamptz,
24233 '
2001-
11-
01 00:
00 -
05:
00'::timestamptz,
24234 '
1 day'::interval, 'America/New_York');
24236 ------------------------
24237 2001-
10-
22 04:
00:
00+
00
24238 2001-
10-
23 04:
00:
00+
00
24239 2001-
10-
24 04:
00:
00+
00
24240 2001-
10-
25 04:
00:
00+
00
24241 2001-
10-
26 04:
00:
00+
00
24242 2001-
10-
27 04:
00:
00+
00
24243 2001-
10-
28 04:
00:
00+
00
24244 2001-
10-
29 05:
00:
00+
00
24245 2001-
10-
30 05:
00:
00+
00
24246 2001-
10-
31 05:
00:
00+
00
24247 2001-
11-
01 05:
00:
00+
00
24252 <table id=
"functions-srf-subscripts">
24253 <title>Subscript Generating Functions
</title>
24257 <entry role=
"func_table_entry"><para role=
"func_signature">
24268 <entry role=
"func_table_entry"><para role=
"func_signature">
24270 <primary>generate_subscripts
</primary>
24272 <function>generate_subscripts
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>dim
</parameter> <type>integer
</type> )
24273 <returnvalue>setof integer
</returnvalue>
24276 Generates a series comprising the valid subscripts of
24277 the
<parameter>dim
</parameter>'th dimension of the given array.
24282 <entry role=
"func_table_entry"><para role=
"func_signature">
24283 <function>generate_subscripts
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>dim
</parameter> <type>integer
</type>,
<parameter>reverse
</parameter> <type>boolean
</type> )
24284 <returnvalue>setof integer
</returnvalue>
24287 Generates a series comprising the valid subscripts of
24288 the
<parameter>dim
</parameter>'th dimension of the given array.
24289 When
<parameter>reverse
</parameter> is true, returns the series in
24298 <function>generate_subscripts
</function> is a convenience function that generates
24299 the set of valid subscripts for the specified dimension of the given
24301 Zero rows are returned for arrays that do not have the requested dimension,
24302 or if any input is
<literal>NULL
</literal>.
24303 Some examples follow:
24306 SELECT generate_subscripts('{NULL,
1,NULL,
2}'::int[],
1) AS s;
24315 -- presenting an array, the subscript and the subscripted
24316 -- value requires a subquery:
24317 SELECT * FROM arrays;
24319 --------------------
24324 SELECT a AS array, s AS subscript, a[s] AS value
24325 FROM (SELECT generate_subscripts(a,
1) AS s, a FROM arrays) foo;
24326 array | subscript | value
24327 ---------------+-----------+-------
24330 {
100,
200,
300} |
1 |
100
24331 {
100,
200,
300} |
2 |
200
24332 {
100,
200,
300} |
3 |
300
24335 -- unnest a
2D array:
24336 CREATE OR REPLACE FUNCTION unnest2(anyarray)
24337 RETURNS SETOF anyelement AS $$
24339 from generate_subscripts($
1,
1) g1(i),
24340 generate_subscripts($
1,
2) g2(j);
24341 $$ LANGUAGE sql IMMUTABLE;
24343 SELECT * FROM unnest2(ARRAY[[
1,
2],[
3,
4]]);
24355 <primary>ordinality
</primary>
24359 When a function in the
<literal>FROM
</literal> clause is suffixed
24360 by
<literal>WITH ORDINALITY
</literal>, a
<type>bigint
</type> column is
24361 appended to the function's output column(s), which starts from
1 and
24362 increments by
1 for each row of the function's output.
24363 This is most useful in the case of set returning
24364 functions such as
<function>unnest()
</function>.
24367 -- set returning function WITH ORDINALITY:
24368 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
24370 -----------------+----
24373 postmaster.opts |
3
24375 postgresql.conf |
5
24396 <sect1 id=
"functions-info">
24397 <title>System Information Functions and Operators
</title>
24400 The functions described in this section are used to obtain various
24401 information about a
<productname>PostgreSQL
</productname> installation.
24404 <sect2 id=
"functions-info-session">
24405 <title>Session Information Functions
</title>
24408 <xref linkend=
"functions-info-session-table"/> shows several
24409 functions that extract session and system information.
24413 In addition to the functions listed in this section, there are a number of
24414 functions related to the statistics system that also provide system
24415 information. See
<xref linkend=
"monitoring-stats-functions"/> for more
24419 <table id=
"functions-info-session-table">
24420 <title>Session Information Functions
</title>
24424 <entry role=
"func_table_entry"><para role=
"func_signature">
24435 <entry role=
"func_table_entry"><para role=
"func_signature">
24437 <primary>current_catalog
</primary>
24439 <function>current_catalog
</function>
24440 <returnvalue>name
</returnvalue>
24442 <para role=
"func_signature">
24444 <primary>current_database
</primary>
24446 <function>current_database
</function> ()
24447 <returnvalue>name
</returnvalue>
24450 Returns the name of the current database. (Databases are
24451 called
<quote>catalogs
</quote> in the SQL standard,
24452 so
<function>current_catalog
</function> is the standard's
24458 <entry role=
"func_table_entry"><para role=
"func_signature">
24460 <primary>current_query
</primary>
24462 <function>current_query
</function> ()
24463 <returnvalue>text
</returnvalue>
24466 Returns the text of the currently executing query, as submitted
24467 by the client (which might contain more than one statement).
24472 <entry role=
"func_table_entry"><para role=
"func_signature">
24474 <primary>current_role
</primary>
24476 <function>current_role
</function>
24477 <returnvalue>name
</returnvalue>
24480 This is equivalent to
<function>current_user
</function>.
24485 <entry role=
"func_table_entry"><para role=
"func_signature">
24487 <primary>current_schema
</primary>
24490 <primary>schema
</primary>
24491 <secondary>current
</secondary>
24493 <function>current_schema
</function>
24494 <returnvalue>name
</returnvalue>
24496 <para role=
"func_signature">
24497 <function>current_schema
</function> ()
24498 <returnvalue>name
</returnvalue>
24501 Returns the name of the schema that is first in the search path (or a
24502 null value if the search path is empty). This is the schema that will
24503 be used for any tables or other named objects that are created without
24504 specifying a target schema.
24509 <entry role=
"func_table_entry"><para role=
"func_signature">
24511 <primary>current_schemas
</primary>
24514 <primary>search path
</primary>
24515 <secondary>current
</secondary>
24517 <function>current_schemas
</function> (
<parameter>include_implicit
</parameter> <type>boolean
</type> )
24518 <returnvalue>name[]
</returnvalue>
24521 Returns an array of the names of all schemas presently in the
24522 effective search path, in their priority order. (Items in the current
24523 <xref linkend=
"guc-search-path"/> setting that do not correspond to
24524 existing, searchable schemas are omitted.) If the Boolean argument
24525 is
<literal>true
</literal>, then implicitly-searched system schemas
24526 such as
<literal>pg_catalog
</literal> are included in the result.
24531 <entry role=
"func_table_entry"><para role=
"func_signature">
24533 <primary>current_user
</primary>
24536 <primary>user
</primary>
24537 <secondary>current
</secondary>
24539 <function>current_user
</function>
24540 <returnvalue>name
</returnvalue>
24543 Returns the user name of the current execution context.
24548 <entry role=
"func_table_entry"><para role=
"func_signature">
24550 <primary>inet_client_addr
</primary>
24552 <function>inet_client_addr
</function> ()
24553 <returnvalue>inet
</returnvalue>
24556 Returns the IP address of the current client,
24557 or
<literal>NULL
</literal> if the current connection is via a
24558 Unix-domain socket.
24563 <entry role=
"func_table_entry"><para role=
"func_signature">
24565 <primary>inet_client_port
</primary>
24567 <function>inet_client_port
</function> ()
24568 <returnvalue>integer
</returnvalue>
24571 Returns the IP port number of the current client,
24572 or
<literal>NULL
</literal> if the current connection is via a
24573 Unix-domain socket.
24578 <entry role=
"func_table_entry"><para role=
"func_signature">
24580 <primary>inet_server_addr
</primary>
24582 <function>inet_server_addr
</function> ()
24583 <returnvalue>inet
</returnvalue>
24586 Returns the IP address on which the server accepted the current
24588 or
<literal>NULL
</literal> if the current connection is via a
24589 Unix-domain socket.
24594 <entry role=
"func_table_entry"><para role=
"func_signature">
24596 <primary>inet_server_port
</primary>
24598 <function>inet_server_port
</function> ()
24599 <returnvalue>integer
</returnvalue>
24602 Returns the IP port number on which the server accepted the current
24604 or
<literal>NULL
</literal> if the current connection is via a
24605 Unix-domain socket.
24610 <entry role=
"func_table_entry"><para role=
"func_signature">
24612 <primary>pg_backend_pid
</primary>
24614 <function>pg_backend_pid
</function> ()
24615 <returnvalue>integer
</returnvalue>
24618 Returns the process ID of the server process attached to the current
24624 <entry role=
"func_table_entry"><para role=
"func_signature">
24626 <primary>pg_blocking_pids
</primary>
24628 <function>pg_blocking_pids
</function> (
<type>integer
</type> )
24629 <returnvalue>integer[]
</returnvalue>
24632 Returns an array of the process ID(s) of the sessions that are
24633 blocking the server process with the specified process ID from
24634 acquiring a lock, or an empty array if there is no such server process
24635 or it is not blocked.
24638 One server process blocks another if it either holds a lock that
24639 conflicts with the blocked process's lock request (hard block), or is
24640 waiting for a lock that would conflict with the blocked process's lock
24641 request and is ahead of it in the wait queue (soft block). When using
24642 parallel queries the result always lists client-visible process IDs
24643 (that is,
<function>pg_backend_pid
</function> results) even if the
24644 actual lock is held or awaited by a child worker process. As a result
24645 of that, there may be duplicated PIDs in the result. Also note that
24646 when a prepared transaction holds a conflicting lock, it will be
24647 represented by a zero process ID.
24650 Frequent calls to this function could have some impact on database
24651 performance, because it needs exclusive access to the lock manager's
24652 shared state for a short time.
24657 <entry role=
"func_table_entry"><para role=
"func_signature">
24659 <primary>pg_conf_load_time
</primary>
24661 <function>pg_conf_load_time
</function> ()
24662 <returnvalue>timestamp with time zone
</returnvalue>
24665 Returns the time when the server configuration files were last loaded.
24666 If the current session was alive at the time, this will be the time
24667 when the session itself re-read the configuration files (so the
24668 reading will vary a little in different sessions). Otherwise it is
24669 the time when the postmaster process re-read the configuration files.
24674 <entry role=
"func_table_entry"><para role=
"func_signature">
24676 <primary>pg_current_logfile
</primary>
24679 <primary>Logging
</primary>
24680 <secondary>pg_current_logfile function
</secondary>
24683 <primary>current_logfiles
</primary>
24684 <secondary>and the pg_current_logfile function
</secondary>
24687 <primary>Logging
</primary>
24688 <secondary>current_logfiles file and the pg_current_logfile
24689 function
</secondary>
24691 <function>pg_current_logfile
</function> (
<optional> <type>text
</type> </optional> )
24692 <returnvalue>text
</returnvalue>
24695 Returns the path name of the log file currently in use by the logging
24696 collector. The path includes the
<xref linkend=
"guc-log-directory"/>
24697 directory and the individual log file name. The result
24698 is
<literal>NULL
</literal> if the logging collector is disabled.
24699 When multiple log files exist, each in a different
24700 format,
<function>pg_current_logfile
</function> without an argument
24701 returns the path of the file having the first format found in the
24702 ordered list:
<literal>stderr
</literal>,
24703 <literal>csvlog
</literal>,
<literal>jsonlog
</literal>.
24704 <literal>NULL
</literal> is returned if no log file has any of these
24706 To request information about a specific log file format, supply
24707 either
<literal>csvlog
</literal>,
<literal>jsonlog
</literal> or
24708 <literal>stderr
</literal> as the
24709 value of the optional parameter. The result is
<literal>NULL
</literal>
24710 if the log format requested is not configured in
24711 <xref linkend=
"guc-log-destination"/>.
24712 The result reflects the contents of
24713 the
<filename>current_logfiles
</filename> file.
24716 This function is restricted to superusers and roles with privileges of
24717 the
<literal>pg_monitor
</literal> role by default, but other users can
24718 be granted EXECUTE to run the function.
24723 <entry role=
"func_table_entry"><para role=
"func_signature">
24725 <primary>pg_my_temp_schema
</primary>
24727 <function>pg_my_temp_schema
</function> ()
24728 <returnvalue>oid
</returnvalue>
24731 Returns the OID of the current session's temporary schema, or zero if
24732 it has none (because it has not created any temporary tables).
24737 <entry role=
"func_table_entry"><para role=
"func_signature">
24739 <primary>pg_is_other_temp_schema
</primary>
24741 <function>pg_is_other_temp_schema
</function> (
<type>oid
</type> )
24742 <returnvalue>boolean
</returnvalue>
24745 Returns true if the given OID is the OID of another session's
24746 temporary schema. (This can be useful, for example, to exclude other
24747 sessions' temporary tables from a catalog display.)
24752 <entry role=
"func_table_entry"><para role=
"func_signature">
24754 <primary>pg_jit_available
</primary>
24756 <function>pg_jit_available
</function> ()
24757 <returnvalue>boolean
</returnvalue>
24760 Returns true if a
<acronym>JIT
</acronym> compiler extension is
24761 available (see
<xref linkend=
"jit"/>) and the
24762 <xref linkend=
"guc-jit"/> configuration parameter is set to
24763 <literal>on
</literal>.
24768 <entry role=
"func_table_entry"><para role=
"func_signature">
24770 <primary>pg_listening_channels
</primary>
24772 <function>pg_listening_channels
</function> ()
24773 <returnvalue>setof text
</returnvalue>
24776 Returns the set of names of asynchronous notification channels that
24777 the current session is listening to.
24782 <entry role=
"func_table_entry"><para role=
"func_signature">
24784 <primary>pg_notification_queue_usage
</primary>
24786 <function>pg_notification_queue_usage
</function> ()
24787 <returnvalue>double precision
</returnvalue>
24790 Returns the fraction (
0–1) of the asynchronous notification
24791 queue's maximum size that is currently occupied by notifications that
24792 are waiting to be processed.
24793 See
<xref linkend=
"sql-listen"/> and
<xref linkend=
"sql-notify"/>
24794 for more information.
24799 <entry role=
"func_table_entry"><para role=
"func_signature">
24801 <primary>pg_postmaster_start_time
</primary>
24803 <function>pg_postmaster_start_time
</function> ()
24804 <returnvalue>timestamp with time zone
</returnvalue>
24807 Returns the time when the server started.
24812 <entry role=
"func_table_entry"><para role=
"func_signature">
24814 <primary>pg_safe_snapshot_blocking_pids
</primary>
24816 <function>pg_safe_snapshot_blocking_pids
</function> (
<type>integer
</type> )
24817 <returnvalue>integer[]
</returnvalue>
24820 Returns an array of the process ID(s) of the sessions that are blocking
24821 the server process with the specified process ID from acquiring a safe
24822 snapshot, or an empty array if there is no such server process or it
24826 A session running a
<literal>SERIALIZABLE
</literal> transaction blocks
24827 a
<literal>SERIALIZABLE READ ONLY DEFERRABLE
</literal> transaction
24828 from acquiring a snapshot until the latter determines that it is safe
24829 to avoid taking any predicate locks. See
24830 <xref linkend=
"xact-serializable"/> for more information about
24831 serializable and deferrable transactions.
24834 Frequent calls to this function could have some impact on database
24835 performance, because it needs access to the predicate lock manager's
24836 shared state for a short time.
24841 <entry role=
"func_table_entry"><para role=
"func_signature">
24843 <primary>pg_trigger_depth
</primary>
24845 <function>pg_trigger_depth
</function> ()
24846 <returnvalue>integer
</returnvalue>
24849 Returns the current nesting level
24850 of
<productname>PostgreSQL
</productname> triggers (
0 if not called,
24851 directly or indirectly, from inside a trigger).
24856 <entry role=
"func_table_entry"><para role=
"func_signature">
24858 <primary>session_user
</primary>
24860 <function>session_user
</function>
24861 <returnvalue>name
</returnvalue>
24864 Returns the session user's name.
24869 <entry role=
"func_table_entry"><para role=
"func_signature">
24871 <primary>system_user
</primary>
24873 <function>system_user
</function>
24874 <returnvalue>text
</returnvalue>
24877 Returns the authentication method and the identity (if any) that the
24878 user presented during the authentication cycle before they were
24879 assigned a database role. It is represented as
24880 <literal>auth_method:identity
</literal> or
24881 <literal>NULL
</literal> if the user has not been authenticated (for
24882 example if
<link linkend=
"auth-trust">Trust authentication
</link> has
24888 <entry role=
"func_table_entry"><para role=
"func_signature">
24890 <primary>user
</primary>
24892 <function>user
</function>
24893 <returnvalue>name
</returnvalue>
24896 This is equivalent to
<function>current_user
</function>.
24905 <function>current_catalog
</function>,
24906 <function>current_role
</function>,
24907 <function>current_schema
</function>,
24908 <function>current_user
</function>,
24909 <function>session_user
</function>,
24910 and
<function>user
</function> have special syntactic status
24911 in
<acronym>SQL
</acronym>: they must be called without trailing
24912 parentheses. In PostgreSQL, parentheses can optionally be used with
24913 <function>current_schema
</function>, but not with the others.
24918 The
<function>session_user
</function> is normally the user who initiated
24919 the current database connection; but superusers can change this setting
24920 with
<xref linkend=
"sql-set-session-authorization"/>.
24921 The
<function>current_user
</function> is the user identifier
24922 that is applicable for permission checking. Normally it is equal
24923 to the session user, but it can be changed with
24924 <xref linkend=
"sql-set-role"/>.
24925 It also changes during the execution of
24926 functions with the attribute
<literal>SECURITY DEFINER
</literal>.
24927 In Unix parlance, the session user is the
<quote>real user
</quote> and
24928 the current user is the
<quote>effective user
</quote>.
24929 <function>current_role
</function> and
<function>user
</function> are
24930 synonyms for
<function>current_user
</function>. (The SQL standard draws
24931 a distinction between
<function>current_role
</function>
24932 and
<function>current_user
</function>, but
<productname>PostgreSQL
</productname>
24933 does not, since it unifies users and roles into a single kind of entity.)
24938 <sect2 id=
"functions-info-access">
24939 <title>Access Privilege Inquiry Functions
</title>
24942 <primary>privilege
</primary>
24943 <secondary>querying
</secondary>
24947 <xref linkend=
"functions-info-access-table"/> lists functions that
24948 allow querying object access privileges programmatically.
24949 (See
<xref linkend=
"ddl-priv"/> for more information about
24951 In these functions, the user whose privileges are being inquired about
24952 can be specified by name or by OID
24953 (
<structname>pg_authid
</structname>.
<structfield>oid
</structfield>), or if
24954 the name is given as
<literal>public
</literal> then the privileges of the
24955 PUBLIC pseudo-role are checked. Also, the
<parameter>user
</parameter>
24956 argument can be omitted entirely, in which case
24957 the
<function>current_user
</function> is assumed.
24958 The object that is being inquired about can be specified either by name or
24959 by OID, too. When specifying by name, a schema name can be included if
24961 The access privilege of interest is specified by a text string, which must
24962 evaluate to one of the appropriate privilege keywords for the object's type
24963 (e.g.,
<literal>SELECT
</literal>). Optionally,
<literal>WITH GRANT
24964 OPTION
</literal> can be added to a privilege type to test whether the
24965 privilege is held with grant option. Also, multiple privilege types can be
24966 listed separated by commas, in which case the result will be true if any of
24967 the listed privileges is held. (Case of the privilege string is not
24968 significant, and extra whitespace is allowed between but not within
24972 SELECT has_table_privilege('myschema.mytable', 'select');
24973 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
24977 <table id=
"functions-info-access-table">
24978 <title>Access Privilege Inquiry Functions
</title>
24982 <entry role=
"func_table_entry"><para role=
"func_signature">
24993 <entry role=
"func_table_entry"><para role=
"func_signature">
24995 <primary>has_any_column_privilege
</primary>
24997 <function>has_any_column_privilege
</function> (
24998 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
24999 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
25000 <parameter>privilege
</parameter> <type>text
</type> )
25001 <returnvalue>boolean
</returnvalue>
25004 Does user have privilege for any column of table?
25005 This succeeds either if the privilege is held for the whole table, or
25006 if there is a column-level grant of the privilege for at least one
25008 Allowable privilege types are
25009 <literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25010 <literal>UPDATE
</literal>, and
<literal>REFERENCES
</literal>.
25015 <entry role=
"func_table_entry"><para role=
"func_signature">
25017 <primary>has_column_privilege
</primary>
25019 <function>has_column_privilege
</function> (
25020 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25021 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
25022 <parameter>column
</parameter> <type>text
</type> or
<type>smallint
</type>,
25023 <parameter>privilege
</parameter> <type>text
</type> )
25024 <returnvalue>boolean
</returnvalue>
25027 Does user have privilege for the specified table column?
25028 This succeeds either if the privilege is held for the whole table, or
25029 if there is a column-level grant of the privilege for the column.
25030 The column can be specified by name or by attribute number
25031 (
<structname>pg_attribute
</structname>.
<structfield>attnum
</structfield>).
25032 Allowable privilege types are
25033 <literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25034 <literal>UPDATE
</literal>, and
<literal>REFERENCES
</literal>.
25039 <entry role=
"func_table_entry"><para role=
"func_signature">
25041 <primary>has_database_privilege
</primary>
25043 <function>has_database_privilege
</function> (
25044 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25045 <parameter>database
</parameter> <type>text
</type> or
<type>oid
</type>,
25046 <parameter>privilege
</parameter> <type>text
</type> )
25047 <returnvalue>boolean
</returnvalue>
25050 Does user have privilege for database?
25051 Allowable privilege types are
25052 <literal>CREATE
</literal>,
25053 <literal>CONNECT
</literal>,
25054 <literal>TEMPORARY
</literal>, and
25055 <literal>TEMP
</literal> (which is equivalent to
25056 <literal>TEMPORARY
</literal>).
25061 <entry role=
"func_table_entry"><para role=
"func_signature">
25063 <primary>has_foreign_data_wrapper_privilege
</primary>
25065 <function>has_foreign_data_wrapper_privilege
</function> (
25066 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25067 <parameter>fdw
</parameter> <type>text
</type> or
<type>oid
</type>,
25068 <parameter>privilege
</parameter> <type>text
</type> )
25069 <returnvalue>boolean
</returnvalue>
25072 Does user have privilege for foreign-data wrapper?
25073 The only allowable privilege type is
<literal>USAGE
</literal>.
25078 <entry role=
"func_table_entry"><para role=
"func_signature">
25080 <primary>has_function_privilege
</primary>
25082 <function>has_function_privilege
</function> (
25083 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25084 <parameter>function
</parameter> <type>text
</type> or
<type>oid
</type>,
25085 <parameter>privilege
</parameter> <type>text
</type> )
25086 <returnvalue>boolean
</returnvalue>
25089 Does user have privilege for function?
25090 The only allowable privilege type is
<literal>EXECUTE
</literal>.
25093 When specifying a function by name rather than by OID, the allowed
25094 input is the same as for the
<type>regprocedure
</type> data type (see
25095 <xref linkend=
"datatype-oid"/>).
25098 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
25104 <entry role=
"func_table_entry"><para role=
"func_signature">
25106 <primary>has_language_privilege
</primary>
25108 <function>has_language_privilege
</function> (
25109 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25110 <parameter>language
</parameter> <type>text
</type> or
<type>oid
</type>,
25111 <parameter>privilege
</parameter> <type>text
</type> )
25112 <returnvalue>boolean
</returnvalue>
25115 Does user have privilege for language?
25116 The only allowable privilege type is
<literal>USAGE
</literal>.
25121 <entry role=
"func_table_entry"><para role=
"func_signature">
25123 <primary>has_largeobject_privilege
</primary>
25125 <function>has_largeobject_privilege
</function> (
25126 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25127 <parameter>largeobject
</parameter> <type>oid
</type>,
25128 <parameter>privilege
</parameter> <type>text
</type> )
25129 <returnvalue>boolean
</returnvalue>
25132 Does user have privilege for large object?
25133 Allowable privilege types are
25134 <literal>SELECT
</literal> and
<literal>UPDATE
</literal>.
25139 <entry role=
"func_table_entry"><para role=
"func_signature">
25141 <primary>has_parameter_privilege
</primary>
25143 <function>has_parameter_privilege
</function> (
25144 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25145 <parameter>parameter
</parameter> <type>text
</type>,
25146 <parameter>privilege
</parameter> <type>text
</type> )
25147 <returnvalue>boolean
</returnvalue>
25150 Does user have privilege for configuration parameter?
25151 The parameter name is case-insensitive.
25152 Allowable privilege types are
<literal>SET
</literal>
25153 and
<literal>ALTER SYSTEM
</literal>.
25158 <entry role=
"func_table_entry"><para role=
"func_signature">
25160 <primary>has_schema_privilege
</primary>
25162 <function>has_schema_privilege
</function> (
25163 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25164 <parameter>schema
</parameter> <type>text
</type> or
<type>oid
</type>,
25165 <parameter>privilege
</parameter> <type>text
</type> )
25166 <returnvalue>boolean
</returnvalue>
25169 Does user have privilege for schema?
25170 Allowable privilege types are
25171 <literal>CREATE
</literal> and
25172 <literal>USAGE
</literal>.
25177 <entry role=
"func_table_entry"><para role=
"func_signature">
25179 <primary>has_sequence_privilege
</primary>
25181 <function>has_sequence_privilege
</function> (
25182 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25183 <parameter>sequence
</parameter> <type>text
</type> or
<type>oid
</type>,
25184 <parameter>privilege
</parameter> <type>text
</type> )
25185 <returnvalue>boolean
</returnvalue>
25188 Does user have privilege for sequence?
25189 Allowable privilege types are
25190 <literal>USAGE
</literal>,
25191 <literal>SELECT
</literal>, and
25192 <literal>UPDATE
</literal>.
25197 <entry role=
"func_table_entry"><para role=
"func_signature">
25199 <primary>has_server_privilege
</primary>
25201 <function>has_server_privilege
</function> (
25202 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25203 <parameter>server
</parameter> <type>text
</type> or
<type>oid
</type>,
25204 <parameter>privilege
</parameter> <type>text
</type> )
25205 <returnvalue>boolean
</returnvalue>
25208 Does user have privilege for foreign server?
25209 The only allowable privilege type is
<literal>USAGE
</literal>.
25214 <entry role=
"func_table_entry"><para role=
"func_signature">
25216 <primary>has_table_privilege
</primary>
25218 <function>has_table_privilege
</function> (
25219 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25220 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
25221 <parameter>privilege
</parameter> <type>text
</type> )
25222 <returnvalue>boolean
</returnvalue>
25225 Does user have privilege for table?
25226 Allowable privilege types
25227 are
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25228 <literal>UPDATE
</literal>,
<literal>DELETE
</literal>,
25229 <literal>TRUNCATE
</literal>,
<literal>REFERENCES
</literal>,
25230 <literal>TRIGGER
</literal>, and
<literal>MAINTAIN
</literal>.
25235 <entry role=
"func_table_entry"><para role=
"func_signature">
25237 <primary>has_tablespace_privilege
</primary>
25239 <function>has_tablespace_privilege
</function> (
25240 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25241 <parameter>tablespace
</parameter> <type>text
</type> or
<type>oid
</type>,
25242 <parameter>privilege
</parameter> <type>text
</type> )
25243 <returnvalue>boolean
</returnvalue>
25246 Does user have privilege for tablespace?
25247 The only allowable privilege type is
<literal>CREATE
</literal>.
25252 <entry role=
"func_table_entry"><para role=
"func_signature">
25254 <primary>has_type_privilege
</primary>
25256 <function>has_type_privilege
</function> (
25257 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25258 <parameter>type
</parameter> <type>text
</type> or
<type>oid
</type>,
25259 <parameter>privilege
</parameter> <type>text
</type> )
25260 <returnvalue>boolean
</returnvalue>
25263 Does user have privilege for data type?
25264 The only allowable privilege type is
<literal>USAGE
</literal>.
25265 When specifying a type by name rather than by OID, the allowed input
25266 is the same as for the
<type>regtype
</type> data type (see
25267 <xref linkend=
"datatype-oid"/>).
25272 <entry role=
"func_table_entry"><para role=
"func_signature">
25274 <primary>pg_has_role
</primary>
25276 <function>pg_has_role
</function> (
25277 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25278 <parameter>role
</parameter> <type>text
</type> or
<type>oid
</type>,
25279 <parameter>privilege
</parameter> <type>text
</type> )
25280 <returnvalue>boolean
</returnvalue>
25283 Does user have privilege for role?
25284 Allowable privilege types are
25285 <literal>MEMBER
</literal>,
<literal>USAGE
</literal>,
25286 and
<literal>SET
</literal>.
25287 <literal>MEMBER
</literal> denotes direct or indirect membership in
25288 the role without regard to what specific privileges may be conferred.
25289 <literal>USAGE
</literal> denotes whether the privileges of the role
25290 are immediately available without doing
<command>SET ROLE
</command>,
25291 while
<literal>SET
</literal> denotes whether it is possible to change
25292 to the role using the
<literal>SET ROLE
</literal> command.
25293 This function does not allow the special case of
25294 setting
<parameter>user
</parameter> to
<literal>public
</literal>,
25295 because the PUBLIC pseudo-role can never be a member of real roles.
25300 <entry role=
"func_table_entry"><para role=
"func_signature">
25302 <primary>row_security_active
</primary>
25304 <function>row_security_active
</function> (
25305 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type> )
25306 <returnvalue>boolean
</returnvalue>
25309 Is row-level security active for the specified table in the context of
25310 the current user and current environment?
25318 <xref linkend=
"functions-aclitem-op-table"/> shows the operators
25319 available for the
<type>aclitem
</type> type, which is the catalog
25320 representation of access privileges. See
<xref linkend=
"ddl-priv"/>
25321 for information about how to read access privilege values.
25324 <table id=
"functions-aclitem-op-table">
25325 <title><type>aclitem
</type> Operators
</title>
25329 <entry role=
"func_table_entry"><para role=
"func_signature">
25343 <entry role=
"func_table_entry"><para role=
"func_signature">
25345 <primary>aclitemeq
</primary>
25347 <type>aclitem
</type> <literal>=
</literal> <type>aclitem
</type>
25348 <returnvalue>boolean
</returnvalue>
25351 Are
<type>aclitem
</type>s equal? (Notice that
25352 type
<type>aclitem
</type> lacks the usual set of comparison
25353 operators; it has only equality. In turn,
<type>aclitem
</type>
25354 arrays can only be compared for equality.)
25357 <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem
</literal>
25358 <returnvalue>f
</returnvalue>
25363 <entry role=
"func_table_entry"><para role=
"func_signature">
25365 <primary>aclcontains
</primary>
25367 <type>aclitem[]
</type> <literal>@
></literal> <type>aclitem
</type>
25368 <returnvalue>boolean
</returnvalue>
25371 Does array contain the specified privileges? (This is true if there
25372 is an array entry that matches the
<type>aclitem
</type>'s grantee and
25373 grantor, and has at least the specified set of privileges.)
25376 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @
> 'calvin=r*/hobbes'::aclitem
</literal>
25377 <returnvalue>t
</returnvalue>
25382 <entry role=
"func_table_entry"><para role=
"func_signature">
25383 <type>aclitem[]
</type> <literal>~
</literal> <type>aclitem
</type>
25384 <returnvalue>boolean
</returnvalue>
25387 This is a deprecated alias for
<literal>@
></literal>.
25390 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem
</literal>
25391 <returnvalue>t
</returnvalue>
25399 <xref linkend=
"functions-aclitem-fn-table"/> shows some additional
25400 functions to manage the
<type>aclitem
</type> type.
25403 <table id=
"functions-aclitem-fn-table">
25404 <title><type>aclitem
</type> Functions
</title>
25408 <entry role=
"func_table_entry"><para role=
"func_signature">
25419 <entry role=
"func_table_entry"><para role=
"func_signature">
25421 <primary>acldefault
</primary>
25423 <function>acldefault
</function> (
25424 <parameter>type
</parameter> <type>"char"</type>,
25425 <parameter>ownerId
</parameter> <type>oid
</type> )
25426 <returnvalue>aclitem[]
</returnvalue>
25429 Constructs an
<type>aclitem
</type> array holding the default access
25430 privileges for an object of type
<parameter>type
</parameter> belonging
25431 to the role with OID
<parameter>ownerId
</parameter>. This represents
25432 the access privileges that will be assumed when an object's
25433 <acronym>ACL
</acronym> entry is null. (The default access privileges
25434 are described in
<xref linkend=
"ddl-priv"/>.)
25435 The
<parameter>type
</parameter> parameter must be one of
25436 'c' for
<literal>COLUMN
</literal>,
25437 'r' for
<literal>TABLE
</literal> and table-like objects,
25438 's' for
<literal>SEQUENCE
</literal>,
25439 'd' for
<literal>DATABASE
</literal>,
25440 'f' for
<literal>FUNCTION
</literal> or
<literal>PROCEDURE
</literal>,
25441 'l' for
<literal>LANGUAGE
</literal>,
25442 'L' for
<literal>LARGE OBJECT
</literal>,
25443 'n' for
<literal>SCHEMA
</literal>,
25444 'p' for
<literal>PARAMETER
</literal>,
25445 't' for
<literal>TABLESPACE
</literal>,
25446 'F' for
<literal>FOREIGN DATA WRAPPER
</literal>,
25447 'S' for
<literal>FOREIGN SERVER
</literal>,
25449 'T' for
<literal>TYPE
</literal> or
<literal>DOMAIN
</literal>.
25454 <entry role=
"func_table_entry"><para role=
"func_signature">
25456 <primary>aclexplode
</primary>
25458 <function>aclexplode
</function> (
<type>aclitem[]
</type> )
25459 <returnvalue>setof record
</returnvalue>
25460 (
<parameter>grantor
</parameter> <type>oid
</type>,
25461 <parameter>grantee
</parameter> <type>oid
</type>,
25462 <parameter>privilege_type
</parameter> <type>text
</type>,
25463 <parameter>is_grantable
</parameter> <type>boolean
</type> )
25466 Returns the
<type>aclitem
</type> array as a set of rows.
25467 If the grantee is the pseudo-role PUBLIC, it is represented by zero in
25468 the
<parameter>grantee
</parameter> column. Each granted privilege is
25469 represented as
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25470 etc (see
<xref linkend=
"privilege-abbrevs-table"/> for a full list).
25471 Note that each privilege is broken out as a separate row, so
25472 only one keyword appears in the
<parameter>privilege_type
</parameter>
25478 <entry role=
"func_table_entry"><para role=
"func_signature">
25480 <primary>makeaclitem
</primary>
25482 <function>makeaclitem
</function> (
25483 <parameter>grantee
</parameter> <type>oid
</type>,
25484 <parameter>grantor
</parameter> <type>oid
</type>,
25485 <parameter>privileges
</parameter> <type>text
</type>,
25486 <parameter>is_grantable
</parameter> <type>boolean
</type> )
25487 <returnvalue>aclitem
</returnvalue>
25490 Constructs an
<type>aclitem
</type> with the given properties.
25491 <parameter>privileges
</parameter> is a comma-separated list of
25492 privilege names such as
<literal>SELECT
</literal>,
25493 <literal>INSERT
</literal>, etc, all of which are set in the
25494 result. (Case of the privilege string is not significant, and
25495 extra whitespace is allowed between but not within privilege
25505 <sect2 id=
"functions-info-schema">
25506 <title>Schema Visibility Inquiry Functions
</title>
25509 <xref linkend=
"functions-info-schema-table"/> shows functions that
25510 determine whether a certain object is
<firstterm>visible
</firstterm> in the
25511 current schema search path.
25512 For example, a table is said to be visible if its
25513 containing schema is in the search path and no table of the same
25514 name appears earlier in the search path. This is equivalent to the
25515 statement that the table can be referenced by name without explicit
25516 schema qualification. Thus, to list the names of all visible tables:
25518 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
25520 For functions and operators, an object in the search path is said to be
25521 visible if there is no object of the same name
<emphasis>and argument data
25522 type(s)
</emphasis> earlier in the path. For operator classes and families,
25523 both the name and the associated index access method are considered.
25527 <primary>search path
</primary>
25528 <secondary>object visibility
</secondary>
25531 <table id=
"functions-info-schema-table">
25532 <title>Schema Visibility Inquiry Functions
</title>
25536 <entry role=
"func_table_entry"><para role=
"func_signature">
25547 <entry role=
"func_table_entry"><para role=
"func_signature">
25549 <primary>pg_collation_is_visible
</primary>
25551 <function>pg_collation_is_visible
</function> (
<parameter>collation
</parameter> <type>oid
</type> )
25552 <returnvalue>boolean
</returnvalue>
25555 Is collation visible in search path?
25560 <entry role=
"func_table_entry"><para role=
"func_signature">
25562 <primary>pg_conversion_is_visible
</primary>
25564 <function>pg_conversion_is_visible
</function> (
<parameter>conversion
</parameter> <type>oid
</type> )
25565 <returnvalue>boolean
</returnvalue>
25568 Is conversion visible in search path?
25573 <entry role=
"func_table_entry"><para role=
"func_signature">
25575 <primary>pg_function_is_visible
</primary>
25577 <function>pg_function_is_visible
</function> (
<parameter>function
</parameter> <type>oid
</type> )
25578 <returnvalue>boolean
</returnvalue>
25581 Is function visible in search path?
25582 (This also works for procedures and aggregates.)
25587 <entry role=
"func_table_entry"><para role=
"func_signature">
25589 <primary>pg_opclass_is_visible
</primary>
25591 <function>pg_opclass_is_visible
</function> (
<parameter>opclass
</parameter> <type>oid
</type> )
25592 <returnvalue>boolean
</returnvalue>
25595 Is operator class visible in search path?
25600 <entry role=
"func_table_entry"><para role=
"func_signature">
25602 <primary>pg_operator_is_visible
</primary>
25604 <function>pg_operator_is_visible
</function> (
<parameter>operator
</parameter> <type>oid
</type> )
25605 <returnvalue>boolean
</returnvalue>
25608 Is operator visible in search path?
25613 <entry role=
"func_table_entry"><para role=
"func_signature">
25615 <primary>pg_opfamily_is_visible
</primary>
25617 <function>pg_opfamily_is_visible
</function> (
<parameter>opclass
</parameter> <type>oid
</type> )
25618 <returnvalue>boolean
</returnvalue>
25621 Is operator family visible in search path?
25626 <entry role=
"func_table_entry"><para role=
"func_signature">
25628 <primary>pg_statistics_obj_is_visible
</primary>
25630 <function>pg_statistics_obj_is_visible
</function> (
<parameter>stat
</parameter> <type>oid
</type> )
25631 <returnvalue>boolean
</returnvalue>
25634 Is statistics object visible in search path?
25639 <entry role=
"func_table_entry"><para role=
"func_signature">
25641 <primary>pg_table_is_visible
</primary>
25643 <function>pg_table_is_visible
</function> (
<parameter>table
</parameter> <type>oid
</type> )
25644 <returnvalue>boolean
</returnvalue>
25647 Is table visible in search path?
25648 (This works for all types of relations, including views, materialized
25649 views, indexes, sequences and foreign tables.)
25654 <entry role=
"func_table_entry"><para role=
"func_signature">
25656 <primary>pg_ts_config_is_visible
</primary>
25658 <function>pg_ts_config_is_visible
</function> (
<parameter>config
</parameter> <type>oid
</type> )
25659 <returnvalue>boolean
</returnvalue>
25662 Is text search configuration visible in search path?
25667 <entry role=
"func_table_entry"><para role=
"func_signature">
25669 <primary>pg_ts_dict_is_visible
</primary>
25671 <function>pg_ts_dict_is_visible
</function> (
<parameter>dict
</parameter> <type>oid
</type> )
25672 <returnvalue>boolean
</returnvalue>
25675 Is text search dictionary visible in search path?
25680 <entry role=
"func_table_entry"><para role=
"func_signature">
25682 <primary>pg_ts_parser_is_visible
</primary>
25684 <function>pg_ts_parser_is_visible
</function> (
<parameter>parser
</parameter> <type>oid
</type> )
25685 <returnvalue>boolean
</returnvalue>
25688 Is text search parser visible in search path?
25693 <entry role=
"func_table_entry"><para role=
"func_signature">
25695 <primary>pg_ts_template_is_visible
</primary>
25697 <function>pg_ts_template_is_visible
</function> (
<parameter>template
</parameter> <type>oid
</type> )
25698 <returnvalue>boolean
</returnvalue>
25701 Is text search template visible in search path?
25706 <entry role=
"func_table_entry"><para role=
"func_signature">
25708 <primary>pg_type_is_visible
</primary>
25710 <function>pg_type_is_visible
</function> (
<parameter>type
</parameter> <type>oid
</type> )
25711 <returnvalue>boolean
</returnvalue>
25714 Is type (or domain) visible in search path?
25722 All these functions require object OIDs to identify the object to be
25723 checked. If you want to test an object by name, it is convenient to use
25724 the OID alias types (
<type>regclass
</type>,
<type>regtype
</type>,
25725 <type>regprocedure
</type>,
<type>regoperator
</type>,
<type>regconfig
</type>,
25726 or
<type>regdictionary
</type>),
25729 SELECT pg_type_is_visible('myschema.widget'::regtype);
25731 Note that it would not make much sense to test a non-schema-qualified
25732 type name in this way
— if the name can be recognized at all, it must be visible.
25737 <sect2 id=
"functions-info-catalog">
25738 <title>System Catalog Information Functions
</title>
25741 <xref linkend=
"functions-info-catalog-table"/> lists functions that
25742 extract information from the system catalogs.
25745 <table id=
"functions-info-catalog-table">
25746 <title>System Catalog Information Functions
</title>
25750 <entry role=
"func_table_entry"><para role=
"func_signature">
25761 <entry id=
"format-type" xreflabel=
"format_type" role=
"func_table_entry"><para role=
"func_signature">
25763 <primary>format_type
</primary>
25765 <function>format_type
</function> (
<parameter>type
</parameter> <type>oid
</type>,
<parameter>typemod
</parameter> <type>integer
</type> )
25766 <returnvalue>text
</returnvalue>
25769 Returns the SQL name for a data type that is identified by its type
25770 OID and possibly a type modifier. Pass NULL for the type modifier if
25771 no specific modifier is known.
25776 <entry role=
"func_table_entry"><para role=
"func_signature">
25778 <primary>pg_basetype
</primary>
25780 <function>pg_basetype
</function> (
<type>regtype
</type> )
25781 <returnvalue>regtype
</returnvalue>
25784 Returns the OID of the base type of a domain identified by its
25785 type OID. If the argument is the OID of a non-domain type,
25786 returns the argument as-is. Returns NULL if the argument is
25787 not a valid type OID. If there's a chain of domain dependencies,
25788 it will recurse until finding the base type.
25791 Assuming
<literal>CREATE DOMAIN mytext AS text
</literal>:
25794 <literal>pg_basetype('mytext'::regtype)
</literal>
25795 <returnvalue>text
</returnvalue>
25800 <entry id=
"pg-char-to-encoding" role=
"func_table_entry"><para role=
"func_signature">
25802 <primary>pg_char_to_encoding
</primary>
25804 <function>pg_char_to_encoding
</function> (
<parameter>encoding
</parameter> <type>name
</type> )
25805 <returnvalue>integer
</returnvalue>
25808 Converts the supplied encoding name into an integer representing the
25809 internal identifier used in some system catalog tables.
25810 Returns
<literal>-
1</literal> if an unknown encoding name is provided.
25815 <entry id=
"pg-encoding-to-char" role=
"func_table_entry"><para role=
"func_signature">
25817 <primary>pg_encoding_to_char
</primary>
25819 <function>pg_encoding_to_char
</function> (
<parameter>encoding
</parameter> <type>integer
</type> )
25820 <returnvalue>name
</returnvalue>
25823 Converts the integer used as the internal identifier of an encoding in some
25824 system catalog tables into a human-readable string.
25825 Returns an empty string if an invalid encoding number is provided.
25830 <entry role=
"func_table_entry"><para role=
"func_signature">
25832 <primary>pg_get_catalog_foreign_keys
</primary>
25834 <function>pg_get_catalog_foreign_keys
</function> ()
25835 <returnvalue>setof record
</returnvalue>
25836 (
<parameter>fktable
</parameter> <type>regclass
</type>,
25837 <parameter>fkcols
</parameter> <type>text[]
</type>,
25838 <parameter>pktable
</parameter> <type>regclass
</type>,
25839 <parameter>pkcols
</parameter> <type>text[]
</type>,
25840 <parameter>is_array
</parameter> <type>boolean
</type>,
25841 <parameter>is_opt
</parameter> <type>boolean
</type> )
25844 Returns a set of records describing the foreign key relationships
25845 that exist within the
<productname>PostgreSQL
</productname> system
25847 The
<parameter>fktable
</parameter> column contains the name of the
25848 referencing catalog, and the
<parameter>fkcols
</parameter> column
25849 contains the name(s) of the referencing column(s). Similarly,
25850 the
<parameter>pktable
</parameter> column contains the name of the
25851 referenced catalog, and the
<parameter>pkcols
</parameter> column
25852 contains the name(s) of the referenced column(s).
25853 If
<parameter>is_array
</parameter> is true, the last referencing
25854 column is an array, each of whose elements should match some entry
25855 in the referenced catalog.
25856 If
<parameter>is_opt
</parameter> is true, the referencing column(s)
25857 are allowed to contain zeroes instead of a valid reference.
25862 <entry role=
"func_table_entry"><para role=
"func_signature">
25864 <primary>pg_get_constraintdef
</primary>
25866 <function>pg_get_constraintdef
</function> (
<parameter>constraint
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
25867 <returnvalue>text
</returnvalue>
25870 Reconstructs the creating command for a constraint.
25871 (This is a decompiled reconstruction, not the original text
25877 <entry role=
"func_table_entry"><para role=
"func_signature">
25879 <primary>pg_get_expr
</primary>
25881 <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> )
25882 <returnvalue>text
</returnvalue>
25885 Decompiles the internal form of an expression stored in the system
25886 catalogs, such as the default value for a column. If the expression
25887 might contain Vars, specify the OID of the relation they refer to as
25888 the second parameter; if no Vars are expected, passing zero is
25894 <entry role=
"func_table_entry"><para role=
"func_signature">
25896 <primary>pg_get_functiondef
</primary>
25898 <function>pg_get_functiondef
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25899 <returnvalue>text
</returnvalue>
25902 Reconstructs the creating command for a function or procedure.
25903 (This is a decompiled reconstruction, not the original text
25905 The result is a complete
<command>CREATE OR REPLACE FUNCTION
</command>
25906 or
<command>CREATE OR REPLACE PROCEDURE
</command> statement.
25911 <entry role=
"func_table_entry"><para role=
"func_signature">
25913 <primary>pg_get_function_arguments
</primary>
25915 <function>pg_get_function_arguments
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25916 <returnvalue>text
</returnvalue>
25919 Reconstructs the argument list of a function or procedure, in the form
25920 it would need to appear in within
<command>CREATE FUNCTION
</command>
25921 (including default values).
25926 <entry role=
"func_table_entry"><para role=
"func_signature">
25928 <primary>pg_get_function_identity_arguments
</primary>
25930 <function>pg_get_function_identity_arguments
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25931 <returnvalue>text
</returnvalue>
25934 Reconstructs the argument list necessary to identify a function or
25935 procedure, in the form it would need to appear in within commands such
25936 as
<command>ALTER FUNCTION
</command>. This form omits default values.
25941 <entry role=
"func_table_entry"><para role=
"func_signature">
25943 <primary>pg_get_function_result
</primary>
25945 <function>pg_get_function_result
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25946 <returnvalue>text
</returnvalue>
25949 Reconstructs the
<literal>RETURNS
</literal> clause of a function, in
25950 the form it would need to appear in within
<command>CREATE
25951 FUNCTION
</command>. Returns
<literal>NULL
</literal> for a procedure.
25956 <entry role=
"func_table_entry"><para role=
"func_signature">
25958 <primary>pg_get_indexdef
</primary>
25960 <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> )
25961 <returnvalue>text
</returnvalue>
25964 Reconstructs the creating command for an index.
25965 (This is a decompiled reconstruction, not the original text
25966 of the command.) If
<parameter>column
</parameter> is supplied and is
25967 not zero, only the definition of that column is reconstructed.
25972 <entry role=
"func_table_entry"><para role=
"func_signature">
25974 <primary>pg_get_keywords
</primary>
25976 <function>pg_get_keywords
</function> ()
25977 <returnvalue>setof record
</returnvalue>
25978 (
<parameter>word
</parameter> <type>text
</type>,
25979 <parameter>catcode
</parameter> <type>"char"</type>,
25980 <parameter>barelabel
</parameter> <type>boolean
</type>,
25981 <parameter>catdesc
</parameter> <type>text
</type>,
25982 <parameter>baredesc
</parameter> <type>text
</type> )
25985 Returns a set of records describing the SQL keywords recognized by the
25986 server. The
<parameter>word
</parameter> column contains the
25987 keyword. The
<parameter>catcode
</parameter> column contains a
25988 category code:
<literal>U
</literal> for an unreserved
25989 keyword,
<literal>C
</literal> for a keyword that can be a column
25990 name,
<literal>T
</literal> for a keyword that can be a type or
25991 function name, or
<literal>R
</literal> for a fully reserved keyword.
25992 The
<parameter>barelabel
</parameter> column
25993 contains
<literal>true
</literal> if the keyword can be used as
25994 a
<quote>bare
</quote> column label in
<command>SELECT
</command> lists,
25995 or
<literal>false
</literal> if it can only be used
25996 after
<literal>AS
</literal>.
25997 The
<parameter>catdesc
</parameter> column contains a
25998 possibly-localized string describing the keyword's category.
25999 The
<parameter>baredesc
</parameter> column contains a
26000 possibly-localized string describing the keyword's column label status.
26005 <entry role=
"func_table_entry"><para role=
"func_signature">
26007 <primary>pg_get_partkeydef
</primary>
26009 <function>pg_get_partkeydef
</function> (
<parameter>table
</parameter> <type>oid
</type> )
26010 <returnvalue>text
</returnvalue>
26013 Reconstructs the definition of a partitioned table's partition
26014 key, in the form it would have in the
<literal>PARTITION
26015 BY
</literal> clause of
<command>CREATE TABLE
</command>.
26016 (This is a decompiled reconstruction, not the original text
26022 <entry role=
"func_table_entry"><para role=
"func_signature">
26024 <primary>pg_get_ruledef
</primary>
26026 <function>pg_get_ruledef
</function> (
<parameter>rule
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26027 <returnvalue>text
</returnvalue>
26030 Reconstructs the creating command for a rule.
26031 (This is a decompiled reconstruction, not the original text
26037 <entry role=
"func_table_entry"><para role=
"func_signature">
26039 <primary>pg_get_serial_sequence
</primary>
26041 <function>pg_get_serial_sequence
</function> (
<parameter>table
</parameter> <type>text
</type>,
<parameter>column
</parameter> <type>text
</type> )
26042 <returnvalue>text
</returnvalue>
26045 Returns the name of the sequence associated with a column,
26046 or NULL if no sequence is associated with the column.
26047 If the column is an identity column, the associated sequence is the
26048 sequence internally created for that column.
26049 For columns created using one of the serial types
26050 (
<type>serial
</type>,
<type>smallserial
</type>,
<type>bigserial
</type>),
26051 it is the sequence created for that serial column definition.
26052 In the latter case, the association can be modified or removed
26053 with
<command>ALTER SEQUENCE OWNED BY
</command>.
26054 (This function probably should have been
26055 called
<function>pg_get_owned_sequence
</function>; its current name
26056 reflects the fact that it has historically been used with serial-type
26057 columns.) The first parameter is a table name with optional
26058 schema, and the second parameter is a column name. Because the first
26059 parameter potentially contains both schema and table names, it is
26060 parsed per usual SQL rules, meaning it is lower-cased by default.
26061 The second parameter, being just a column name, is treated literally
26062 and so has its case preserved. The result is suitably formatted
26063 for passing to the sequence functions (see
26064 <xref linkend=
"functions-sequence"/>).
26067 A typical use is in reading the current value of the sequence for an
26068 identity or serial column, for example:
26070 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
26076 <entry role=
"func_table_entry"><para role=
"func_signature">
26078 <primary>pg_get_statisticsobjdef
</primary>
26080 <function>pg_get_statisticsobjdef
</function> (
<parameter>statobj
</parameter> <type>oid
</type> )
26081 <returnvalue>text
</returnvalue>
26084 Reconstructs the creating command for an extended statistics object.
26085 (This is a decompiled reconstruction, not the original text
26091 <entry role=
"func_table_entry"><para role=
"func_signature">
26093 <primary>pg_get_triggerdef
</primary>
26095 <function>pg_get_triggerdef
</function> (
<parameter>trigger
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26096 <returnvalue>text
</returnvalue>
26099 Reconstructs the creating command for a trigger.
26100 (This is a decompiled reconstruction, not the original text
26106 <entry role=
"func_table_entry"><para role=
"func_signature">
26108 <primary>pg_get_userbyid
</primary>
26110 <function>pg_get_userbyid
</function> (
<parameter>role
</parameter> <type>oid
</type> )
26111 <returnvalue>name
</returnvalue>
26114 Returns a role's name given its OID.
26119 <entry role=
"func_table_entry"><para role=
"func_signature">
26121 <primary>pg_get_viewdef
</primary>
26123 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26124 <returnvalue>text
</returnvalue>
26127 Reconstructs the underlying
<command>SELECT
</command> command for a
26128 view or materialized view. (This is a decompiled reconstruction, not
26129 the original text of the command.)
26134 <entry role=
"func_table_entry"><para role=
"func_signature">
26135 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>oid
</type>,
<parameter>wrap_column
</parameter> <type>integer
</type> )
26136 <returnvalue>text
</returnvalue>
26139 Reconstructs the underlying
<command>SELECT
</command> command for a
26140 view or materialized view. (This is a decompiled reconstruction, not
26141 the original text of the command.) In this form of the function,
26142 pretty-printing is always enabled, and long lines are wrapped to try
26143 to keep them shorter than the specified number of columns.
26148 <entry role=
"func_table_entry"><para role=
"func_signature">
26149 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>text
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26150 <returnvalue>text
</returnvalue>
26153 Reconstructs the underlying
<command>SELECT
</command> command for a
26154 view or materialized view, working from a textual name for the view
26155 rather than its OID. (This is deprecated; use the OID variant
26161 <entry role=
"func_table_entry"><para role=
"func_signature">
26163 <primary>pg_index_column_has_property
</primary>
26165 <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> )
26166 <returnvalue>boolean
</returnvalue>
26169 Tests whether an index column has the named property.
26170 Common index column properties are listed in
26171 <xref linkend=
"functions-info-index-column-props"/>.
26172 (Note that extension access methods can define additional property
26173 names for their indexes.)
26174 <literal>NULL
</literal> is returned if the property name is not known
26175 or does not apply to the particular object, or if the OID or column
26176 number does not identify a valid object.
26181 <entry role=
"func_table_entry"><para role=
"func_signature">
26183 <primary>pg_index_has_property
</primary>
26185 <function>pg_index_has_property
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>property
</parameter> <type>text
</type> )
26186 <returnvalue>boolean
</returnvalue>
26189 Tests whether an index has the named property.
26190 Common index properties are listed in
26191 <xref linkend=
"functions-info-index-props"/>.
26192 (Note that extension access methods can define additional property
26193 names for their indexes.)
26194 <literal>NULL
</literal> is returned if the property name is not known
26195 or does not apply to the particular object, or if the OID does not
26196 identify a valid object.
26201 <entry role=
"func_table_entry"><para role=
"func_signature">
26203 <primary>pg_indexam_has_property
</primary>
26205 <function>pg_indexam_has_property
</function> (
<parameter>am
</parameter> <type>oid
</type>,
<parameter>property
</parameter> <type>text
</type> )
26206 <returnvalue>boolean
</returnvalue>
26209 Tests whether an index access method has the named property.
26210 Access method properties are listed in
26211 <xref linkend=
"functions-info-indexam-props"/>.
26212 <literal>NULL
</literal> is returned if the property name is not known
26213 or does not apply to the particular object, or if the OID does not
26214 identify a valid object.
26219 <entry role=
"func_table_entry"><para role=
"func_signature">
26221 <primary>pg_options_to_table
</primary>
26223 <function>pg_options_to_table
</function> (
<parameter>options_array
</parameter> <type>text[]
</type> )
26224 <returnvalue>setof record
</returnvalue>
26225 (
<parameter>option_name
</parameter> <type>text
</type>,
26226 <parameter>option_value
</parameter> <type>text
</type> )
26229 Returns the set of storage options represented by a value from
26230 <structname>pg_class
</structname>.
<structfield>reloptions
</structfield> or
26231 <structname>pg_attribute
</structname>.
<structfield>attoptions
</structfield>.
26236 <entry role=
"func_table_entry"><para role=
"func_signature">
26238 <primary>pg_settings_get_flags
</primary>
26240 <function>pg_settings_get_flags
</function> (
<parameter>guc
</parameter> <type>text
</type> )
26241 <returnvalue>text[]
</returnvalue>
26244 Returns an array of the flags associated with the given GUC, or
26245 <literal>NULL
</literal> if it does not exist. The result is
26246 an empty array if the GUC exists but there are no flags to show.
26247 Only the most useful flags listed in
26248 <xref linkend=
"functions-pg-settings-flags"/> are exposed.
26253 <entry role=
"func_table_entry"><para role=
"func_signature">
26255 <primary>pg_tablespace_databases
</primary>
26257 <function>pg_tablespace_databases
</function> (
<parameter>tablespace
</parameter> <type>oid
</type> )
26258 <returnvalue>setof oid
</returnvalue>
26261 Returns the set of OIDs of databases that have objects stored in the
26262 specified tablespace. If this function returns any rows, the
26263 tablespace is not empty and cannot be dropped. To identify the specific
26264 objects populating the tablespace, you will need to connect to the
26265 database(s) identified by
<function>pg_tablespace_databases
</function>
26266 and query their
<structname>pg_class
</structname> catalogs.
26271 <entry role=
"func_table_entry"><para role=
"func_signature">
26273 <primary>pg_tablespace_location
</primary>
26275 <function>pg_tablespace_location
</function> (
<parameter>tablespace
</parameter> <type>oid
</type> )
26276 <returnvalue>text
</returnvalue>
26279 Returns the file system path that this tablespace is located in.
26284 <entry role=
"func_table_entry"><para role=
"func_signature">
26286 <primary>pg_typeof
</primary>
26288 <function>pg_typeof
</function> (
<type>"any"</type> )
26289 <returnvalue>regtype
</returnvalue>
26292 Returns the OID of the data type of the value that is passed to it.
26293 This can be helpful for troubleshooting or dynamically constructing
26294 SQL queries. The function is declared as
26295 returning
<type>regtype
</type>, which is an OID alias type (see
26296 <xref linkend=
"datatype-oid"/>); this means that it is the same as an
26297 OID for comparison purposes but displays as a type name.
26300 <literal>pg_typeof(
33)
</literal>
26301 <returnvalue>integer
</returnvalue>
26306 <entry role=
"func_table_entry"><para role=
"func_signature">
26308 <primary>COLLATION FOR
</primary>
26310 <function>COLLATION FOR
</function> (
<type>"any"</type> )
26311 <returnvalue>text
</returnvalue>
26314 Returns the name of the collation of the value that is passed to it.
26315 The value is quoted and schema-qualified if necessary. If no
26316 collation was derived for the argument expression,
26317 then
<literal>NULL
</literal> is returned. If the argument is not of a
26318 collatable data type, then an error is raised.
26321 <literal>collation for ('foo'::text)
</literal>
26322 <returnvalue>"default"</returnvalue>
26325 <literal>collation for ('foo' COLLATE
"de_DE")
</literal>
26326 <returnvalue>"de_DE"</returnvalue>
26331 <entry role=
"func_table_entry"><para role=
"func_signature">
26333 <primary>to_regclass
</primary>
26335 <function>to_regclass
</function> (
<type>text
</type> )
26336 <returnvalue>regclass
</returnvalue>
26339 Translates a textual relation name to its OID. A similar result is
26340 obtained by casting the string to type
<type>regclass
</type> (see
26341 <xref linkend=
"datatype-oid"/>); however, this function will return
26342 <literal>NULL
</literal> rather than throwing an error if the name is
26348 <entry role=
"func_table_entry"><para role=
"func_signature">
26350 <primary>to_regcollation
</primary>
26352 <function>to_regcollation
</function> (
<type>text
</type> )
26353 <returnvalue>regcollation
</returnvalue>
26356 Translates a textual collation name to its OID. A similar result is
26357 obtained by casting the string to type
<type>regcollation
</type> (see
26358 <xref linkend=
"datatype-oid"/>); however, this function will return
26359 <literal>NULL
</literal> rather than throwing an error if the name is
26365 <entry role=
"func_table_entry"><para role=
"func_signature">
26367 <primary>to_regnamespace
</primary>
26369 <function>to_regnamespace
</function> (
<type>text
</type> )
26370 <returnvalue>regnamespace
</returnvalue>
26373 Translates a textual schema name to its OID. A similar result is
26374 obtained by casting the string to type
<type>regnamespace
</type> (see
26375 <xref linkend=
"datatype-oid"/>); however, this function will return
26376 <literal>NULL
</literal> rather than throwing an error if the name is
26382 <entry role=
"func_table_entry"><para role=
"func_signature">
26384 <primary>to_regoper
</primary>
26386 <function>to_regoper
</function> (
<type>text
</type> )
26387 <returnvalue>regoper
</returnvalue>
26390 Translates a textual operator name to its OID. A similar result is
26391 obtained by casting the string to type
<type>regoper
</type> (see
26392 <xref linkend=
"datatype-oid"/>); however, this function will return
26393 <literal>NULL
</literal> rather than throwing an error if the name is
26394 not found or is ambiguous.
26399 <entry role=
"func_table_entry"><para role=
"func_signature">
26401 <primary>to_regoperator
</primary>
26403 <function>to_regoperator
</function> (
<type>text
</type> )
26404 <returnvalue>regoperator
</returnvalue>
26407 Translates a textual operator name (with parameter types) to its OID. A similar result is
26408 obtained by casting the string to type
<type>regoperator
</type> (see
26409 <xref linkend=
"datatype-oid"/>); however, this function will return
26410 <literal>NULL
</literal> rather than throwing an error if the name is
26416 <entry role=
"func_table_entry"><para role=
"func_signature">
26418 <primary>to_regproc
</primary>
26420 <function>to_regproc
</function> (
<type>text
</type> )
26421 <returnvalue>regproc
</returnvalue>
26424 Translates a textual function or procedure name to its OID. A similar result is
26425 obtained by casting the string to type
<type>regproc
</type> (see
26426 <xref linkend=
"datatype-oid"/>); however, this function will return
26427 <literal>NULL
</literal> rather than throwing an error if the name is
26428 not found or is ambiguous.
26433 <entry role=
"func_table_entry"><para role=
"func_signature">
26435 <primary>to_regprocedure
</primary>
26437 <function>to_regprocedure
</function> (
<type>text
</type> )
26438 <returnvalue>regprocedure
</returnvalue>
26441 Translates a textual function or procedure name (with argument types) to its OID. A similar result is
26442 obtained by casting the string to type
<type>regprocedure
</type> (see
26443 <xref linkend=
"datatype-oid"/>); however, this function will return
26444 <literal>NULL
</literal> rather than throwing an error if the name is
26450 <entry role=
"func_table_entry"><para role=
"func_signature">
26452 <primary>to_regrole
</primary>
26454 <function>to_regrole
</function> (
<type>text
</type> )
26455 <returnvalue>regrole
</returnvalue>
26458 Translates a textual role name to its OID. A similar result is
26459 obtained by casting the string to type
<type>regrole
</type> (see
26460 <xref linkend=
"datatype-oid"/>); however, this function will return
26461 <literal>NULL
</literal> rather than throwing an error if the name is
26467 <entry id=
"to-regtype" xreflabel=
"to_regtype" role=
"func_table_entry"><para role=
"func_signature">
26469 <primary>to_regtype
</primary>
26471 <function>to_regtype
</function> (
<type>text
</type> )
26472 <returnvalue>regtype
</returnvalue>
26475 Parses a string of text, extracts a potential type name from it,
26476 and translates that name into a type OID. A syntax error in the
26477 string will result in an error; but if the string is a
26478 syntactically valid type name that happens not to be found in the
26479 catalogs, the result is
<literal>NULL
</literal>. A similar result
26480 is obtained by casting the string to type
<type>regtype
</type>
26481 (see
<xref linkend=
"datatype-oid"/>), except that that will throw
26482 error for name not found.
26487 <entry role=
"func_table_entry"><para role=
"func_signature">
26489 <primary>to_regtypemod
</primary>
26491 <function>to_regtypemod
</function> (
<type>text
</type> )
26492 <returnvalue>integer
</returnvalue>
26495 Parses a string of text, extracts a potential type name from it,
26496 and translates its type modifier, if any. A syntax error in the
26497 string will result in an error; but if the string is a
26498 syntactically valid type name that happens not to be found in the
26499 catalogs, the result is
<literal>NULL
</literal>. The result is
26500 <literal>-
1</literal> if no type modifier is present.
26503 <function>to_regtypemod
</function> can be combined with
26504 <xref linkend=
"to-regtype"/> to produce appropriate inputs for
26505 <xref linkend=
"format-type"/>, allowing a string representing a
26506 type name to be canonicalized.
26509 <literal>format_type(to_regtype('varchar(
32)'), to_regtypemod('varchar(
32)'))
</literal>
26510 <returnvalue>character varying(
32)
</returnvalue>
26518 Most of the functions that reconstruct (decompile) database objects
26519 have an optional
<parameter>pretty
</parameter> flag, which
26520 if
<literal>true
</literal> causes the result to
26521 be
<quote>pretty-printed
</quote>. Pretty-printing suppresses unnecessary
26522 parentheses and adds whitespace for legibility.
26523 The pretty-printed format is more readable, but the default format
26524 is more likely to be interpreted the same way by future versions of
26525 <productname>PostgreSQL
</productname>; so avoid using pretty-printed output
26526 for dump purposes. Passing
<literal>false
</literal> for
26527 the
<parameter>pretty
</parameter> parameter yields the same result as
26528 omitting the parameter.
26531 <table id=
"functions-info-index-column-props">
26532 <title>Index Column Properties
</title>
26535 <row><entry>Name
</entry><entry>Description
</entry></row>
26539 <entry><literal>asc
</literal></entry>
26540 <entry>Does the column sort in ascending order on a forward scan?
26544 <entry><literal>desc
</literal></entry>
26545 <entry>Does the column sort in descending order on a forward scan?
26549 <entry><literal>nulls_first
</literal></entry>
26550 <entry>Does the column sort with nulls first on a forward scan?
26554 <entry><literal>nulls_last
</literal></entry>
26555 <entry>Does the column sort with nulls last on a forward scan?
26559 <entry><literal>orderable
</literal></entry>
26560 <entry>Does the column possess any defined sort ordering?
26564 <entry><literal>distance_orderable
</literal></entry>
26565 <entry>Can the column be scanned in order by a
<quote>distance
</quote>
26566 operator, for example
<literal>ORDER BY col
<-
> constant
</literal> ?
26570 <entry><literal>returnable
</literal></entry>
26571 <entry>Can the column value be returned by an index-only scan?
26575 <entry><literal>search_array
</literal></entry>
26576 <entry>Does the column natively support
<literal>col = ANY(array)
</literal>
26581 <entry><literal>search_nulls
</literal></entry>
26582 <entry>Does the column support
<literal>IS NULL
</literal> and
26583 <literal>IS NOT NULL
</literal> searches?
26590 <table id=
"functions-info-index-props">
26591 <title>Index Properties
</title>
26594 <row><entry>Name
</entry><entry>Description
</entry></row>
26598 <entry><literal>clusterable
</literal></entry>
26599 <entry>Can the index be used in a
<literal>CLUSTER
</literal> command?
26603 <entry><literal>index_scan
</literal></entry>
26604 <entry>Does the index support plain (non-bitmap) scans?
26608 <entry><literal>bitmap_scan
</literal></entry>
26609 <entry>Does the index support bitmap scans?
26613 <entry><literal>backward_scan
</literal></entry>
26614 <entry>Can the scan direction be changed in mid-scan (to
26615 support
<literal>FETCH BACKWARD
</literal> on a cursor without
26616 needing materialization)?
26623 <table id=
"functions-info-indexam-props">
26624 <title>Index Access Method Properties
</title>
26627 <row><entry>Name
</entry><entry>Description
</entry></row>
26631 <entry><literal>can_order
</literal></entry>
26632 <entry>Does the access method support
<literal>ASC
</literal>,
26633 <literal>DESC
</literal> and related keywords in
26634 <literal>CREATE INDEX
</literal>?
26638 <entry><literal>can_unique
</literal></entry>
26639 <entry>Does the access method support unique indexes?
26643 <entry><literal>can_multi_col
</literal></entry>
26644 <entry>Does the access method support indexes with multiple columns?
26648 <entry><literal>can_exclude
</literal></entry>
26649 <entry>Does the access method support exclusion constraints?
26653 <entry><literal>can_include
</literal></entry>
26654 <entry>Does the access method support the
<literal>INCLUDE
</literal>
26655 clause of
<literal>CREATE INDEX
</literal>?
26662 <table id=
"functions-pg-settings-flags">
26663 <title>GUC Flags
</title>
26666 <row><entry>Flag
</entry><entry>Description
</entry></row>
26670 <entry><literal>EXPLAIN
</literal></entry>
26671 <entry>Parameters with this flag are included in
26672 <command>EXPLAIN (SETTINGS)
</command> commands.
26676 <entry><literal>NO_SHOW_ALL
</literal></entry>
26677 <entry>Parameters with this flag are excluded from
26678 <command>SHOW ALL
</command> commands.
26682 <entry><literal>NO_RESET
</literal></entry>
26683 <entry>Parameters with this flag do not support
26684 <command>RESET
</command> commands.
26688 <entry><literal>NO_RESET_ALL
</literal></entry>
26689 <entry>Parameters with this flag are excluded from
26690 <command>RESET ALL
</command> commands.
26694 <entry><literal>NOT_IN_SAMPLE
</literal></entry>
26695 <entry>Parameters with this flag are not included in
26696 <filename>postgresql.conf
</filename> by default.
26700 <entry><literal>RUNTIME_COMPUTED
</literal></entry>
26701 <entry>Parameters with this flag are runtime-computed ones.
26710 <sect2 id=
"functions-info-object">
26711 <title>Object Information and Addressing Functions
</title>
26714 <xref linkend=
"functions-info-object-table"/> lists functions related to
26715 database object identification and addressing.
26718 <table id=
"functions-info-object-table">
26719 <title>Object Information and Addressing Functions
</title>
26723 <entry role=
"func_table_entry"><para role=
"func_signature">
26734 <entry role=
"func_table_entry"><para role=
"func_signature">
26736 <primary>pg_get_acl
</primary>
26738 <function>pg_get_acl
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
26739 <returnvalue>aclitem[]
</returnvalue>
26742 Returns the
<acronym>ACL
</acronym> for a database object, specified
26743 by catalog OID, object OID and sub-object ID. This function returns
26744 <literal>NULL
</literal> values for undefined objects.
26749 <entry role=
"func_table_entry"><para role=
"func_signature">
26751 <primary>pg_describe_object
</primary>
26753 <function>pg_describe_object
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
26754 <returnvalue>text
</returnvalue>
26757 Returns a textual description of a database object identified by
26758 catalog OID, object OID, and sub-object ID (such as a column number
26759 within a table; the sub-object ID is zero when referring to a whole
26760 object). This description is intended to be human-readable, and might
26761 be translated, depending on server configuration. This is especially
26762 useful to determine the identity of an object referenced in the
26763 <structname>pg_depend
</structname> catalog. This function returns
26764 <literal>NULL
</literal> values for undefined objects.
26769 <entry role=
"func_table_entry"><para role=
"func_signature">
26771 <primary>pg_identify_object
</primary>
26773 <function>pg_identify_object
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
26774 <returnvalue>record
</returnvalue>
26775 (
<parameter>type
</parameter> <type>text
</type>,
26776 <parameter>schema
</parameter> <type>text
</type>,
26777 <parameter>name
</parameter> <type>text
</type>,
26778 <parameter>identity
</parameter> <type>text
</type> )
26781 Returns a row containing enough information to uniquely identify the
26782 database object specified by catalog OID, object OID and sub-object
26784 This information is intended to be machine-readable, and is never
26786 <parameter>type
</parameter> identifies the type of database object;
26787 <parameter>schema
</parameter> is the schema name that the object
26788 belongs in, or
<literal>NULL
</literal> for object types that do not
26790 <parameter>name
</parameter> is the name of the object, quoted if
26791 necessary, if the name (along with schema name, if pertinent) is
26792 sufficient to uniquely identify the object,
26793 otherwise
<literal>NULL
</literal>;
26794 <parameter>identity
</parameter> is the complete object identity, with
26795 the precise format depending on object type, and each name within the
26796 format being schema-qualified and quoted as necessary. Undefined
26797 objects are identified with
<literal>NULL
</literal> values.
26802 <entry role=
"func_table_entry"><para role=
"func_signature">
26804 <primary>pg_identify_object_as_address
</primary>
26806 <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> )
26807 <returnvalue>record
</returnvalue>
26808 (
<parameter>type
</parameter> <type>text
</type>,
26809 <parameter>object_names
</parameter> <type>text[]
</type>,
26810 <parameter>object_args
</parameter> <type>text[]
</type> )
26813 Returns a row containing enough information to uniquely identify the
26814 database object specified by catalog OID, object OID and sub-object
26816 The returned information is independent of the current server, that
26817 is, it could be used to identify an identically named object in
26819 <parameter>type
</parameter> identifies the type of database object;
26820 <parameter>object_names
</parameter> and
26821 <parameter>object_args
</parameter>
26822 are text arrays that together form a reference to the object.
26823 These three values can be passed
26824 to
<function>pg_get_object_address
</function> to obtain the internal
26825 address of the object.
26830 <entry role=
"func_table_entry"><para role=
"func_signature">
26832 <primary>pg_get_object_address
</primary>
26834 <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> )
26835 <returnvalue>record
</returnvalue>
26836 (
<parameter>classid
</parameter> <type>oid
</type>,
26837 <parameter>objid
</parameter> <type>oid
</type>,
26838 <parameter>objsubid
</parameter> <type>integer
</type> )
26841 Returns a row containing enough information to uniquely identify the
26842 database object specified by a type code and object name and argument
26844 The returned values are the ones that would be used in system catalogs
26845 such as
<structname>pg_depend
</structname>; they can be passed to
26846 other system functions such as
<function>pg_describe_object
</function>
26847 or
<function>pg_identify_object
</function>.
26848 <parameter>classid
</parameter> is the OID of the system catalog
26849 containing the object;
26850 <parameter>objid
</parameter> is the OID of the object itself, and
26851 <parameter>objsubid
</parameter> is the sub-object ID, or zero if none.
26852 This function is the inverse
26853 of
<function>pg_identify_object_as_address
</function>.
26854 Undefined objects are identified with
<literal>NULL
</literal> values.
26862 <function>pg_get_acl
</function> is useful for retrieving and inspecting
26863 the privileges associated with database objects without looking at
26864 specific catalogs. For example, to retrieve all the granted privileges
26865 on objects in the current database:
26868 (pg_identify_object(s.classid,s.objid,s.objsubid)).*,
26869 pg_catalog.pg_get_acl(s.classid,s.objid,s.objsubid) AS acl
26870 FROM pg_catalog.pg_shdepend AS s
26871 JOIN pg_catalog.pg_database AS d
26872 ON d.datname = current_database() AND
26874 JOIN pg_catalog.pg_authid AS a
26875 ON a.oid = s.refobjid AND
26876 s.refclassid = 'pg_authid'::regclass
26877 WHERE s.deptype = 'a';
26878 -[ RECORD
1 ]-----------------------------------------
26882 identity | public.testtab
26883 acl | {postgres=arwdDxtm/postgres,foo=r/postgres}
26889 <sect2 id=
"functions-info-comment">
26890 <title>Comment Information Functions
</title>
26893 <primary>comment
</primary>
26894 <secondary sortas=
"database objects">about database objects
</secondary>
26898 The functions shown in
<xref linkend=
"functions-info-comment-table"/>
26899 extract comments previously stored with the
<xref linkend=
"sql-comment"/>
26900 command. A null value is returned if no
26901 comment could be found for the specified parameters.
26904 <table id=
"functions-info-comment-table">
26905 <title>Comment Information Functions
</title>
26909 <entry role=
"func_table_entry"><para role=
"func_signature">
26920 <entry role=
"func_table_entry"><para role=
"func_signature">
26922 <primary>col_description
</primary>
26924 <function>col_description
</function> (
<parameter>table
</parameter> <type>oid
</type>,
<parameter>column
</parameter> <type>integer
</type> )
26925 <returnvalue>text
</returnvalue>
26928 Returns the comment for a table column, which is specified by the OID
26929 of its table and its column number.
26930 (
<function>obj_description
</function> cannot be used for table
26931 columns, since columns do not have OIDs of their own.)
26936 <entry role=
"func_table_entry"><para role=
"func_signature">
26938 <primary>obj_description
</primary>
26940 <function>obj_description
</function> (
<parameter>object
</parameter> <type>oid
</type>,
<parameter>catalog
</parameter> <type>name
</type> )
26941 <returnvalue>text
</returnvalue>
26944 Returns the comment for a database object specified by its OID and the
26945 name of the containing system catalog. For
26946 example,
<literal>obj_description(
123456, 'pg_class')
</literal> would
26947 retrieve the comment for the table with OID
123456.
26952 <entry role=
"func_table_entry"><para role=
"func_signature">
26953 <function>obj_description
</function> (
<parameter>object
</parameter> <type>oid
</type> )
26954 <returnvalue>text
</returnvalue>
26957 Returns the comment for a database object specified by its OID alone.
26958 This is
<emphasis>deprecated
</emphasis> since there is no guarantee
26959 that OIDs are unique across different system catalogs; therefore, the
26960 wrong comment might be returned.
26965 <entry role=
"func_table_entry"><para role=
"func_signature">
26967 <primary>shobj_description
</primary>
26969 <function>shobj_description
</function> (
<parameter>object
</parameter> <type>oid
</type>,
<parameter>catalog
</parameter> <type>name
</type> )
26970 <returnvalue>text
</returnvalue>
26973 Returns the comment for a shared database object specified by its OID
26974 and the name of the containing system catalog. This is just
26975 like
<function>obj_description
</function> except that it is used for
26976 retrieving comments on shared objects (that is, databases, roles, and
26977 tablespaces). Some system catalogs are global to all databases within
26978 each cluster, and the descriptions for objects in them are stored
26988 <sect2 id=
"functions-info-validity">
26989 <title>Data Validity Checking Functions
</title>
26992 The functions shown in
<xref linkend=
"functions-info-validity-table"/>
26993 can be helpful for checking validity of proposed input data.
26996 <table id=
"functions-info-validity-table">
26997 <title>Data Validity Checking Functions
</title>
27001 <entry role=
"func_table_entry"><para role=
"func_signature">
27015 <entry role=
"func_table_entry"><para role=
"func_signature">
27017 <primary>pg_input_is_valid
</primary>
27019 <function>pg_input_is_valid
</function> (
27020 <parameter>string
</parameter> <type>text
</type>,
27021 <parameter>type
</parameter> <type>text
</type>
27023 <returnvalue>boolean
</returnvalue>
27026 Tests whether the given
<parameter>string
</parameter> is valid
27027 input for the specified data type, returning true or false.
27030 This function will only work as desired if the data type's input
27031 function has been updated to report invalid input as
27032 a
<quote>soft
</quote> error. Otherwise, invalid input will abort
27033 the transaction, just as if the string had been cast to the type
27037 <literal>pg_input_is_valid('
42', 'integer')
</literal>
27038 <returnvalue>t
</returnvalue>
27041 <literal>pg_input_is_valid('
42000000000', 'integer')
</literal>
27042 <returnvalue>f
</returnvalue>
27045 <literal>pg_input_is_valid('
1234.567', 'numeric(
7,
4)')
</literal>
27046 <returnvalue>f
</returnvalue>
27050 <entry role=
"func_table_entry"><para role=
"func_signature">
27052 <primary>pg_input_error_info
</primary>
27054 <function>pg_input_error_info
</function> (
27055 <parameter>string
</parameter> <type>text
</type>,
27056 <parameter>type
</parameter> <type>text
</type>
27058 <returnvalue>record
</returnvalue>
27059 (
<parameter>message
</parameter> <type>text
</type>,
27060 <parameter>detail
</parameter> <type>text
</type>,
27061 <parameter>hint
</parameter> <type>text
</type>,
27062 <parameter>sql_error_code
</parameter> <type>text
</type> )
27065 Tests whether the given
<parameter>string
</parameter> is valid
27066 input for the specified data type; if not, return the details of
27067 the error that would have been thrown. If the input is valid, the
27068 results are NULL. The inputs are the same as
27069 for
<function>pg_input_is_valid
</function>.
27072 This function will only work as desired if the data type's input
27073 function has been updated to report invalid input as
27074 a
<quote>soft
</quote> error. Otherwise, invalid input will abort
27075 the transaction, just as if the string had been cast to the type
27079 <literal>SELECT * FROM pg_input_error_info('
42000000000', 'integer')
</literal>
27080 <returnvalue></returnvalue>
27082 message | detail | hint | sql_error_code
27083 ------------------------------------------------------+--------+------+----------------
27084 value
"42000000000" is out of range for type integer | | |
22003
27094 <sect2 id=
"functions-info-snapshot">
27095 <title>Transaction ID and Snapshot Information Functions
</title>
27098 The functions shown in
<xref linkend=
"functions-pg-snapshot"/>
27099 provide server transaction information in an exportable form. The main
27100 use of these functions is to determine which transactions were committed
27101 between two snapshots.
27104 <table id=
"functions-pg-snapshot">
27105 <title>Transaction ID and Snapshot Information Functions
</title>
27109 <entry role=
"func_table_entry"><para role=
"func_signature">
27120 <entry role=
"func_table_entry"><para role=
"func_signature">
27122 <primary>pg_current_xact_id
</primary>
27124 <function>pg_current_xact_id
</function> ()
27125 <returnvalue>xid8
</returnvalue>
27128 Returns the current transaction's ID. It will assign a new one if the
27129 current transaction does not have one already (because it has not
27130 performed any database updates); see
<xref
27131 linkend=
"transaction-id"/> for details. If executed in a
27132 subtransaction, this will return the top-level transaction ID;
27133 see
<xref linkend=
"subxacts"/> for details.
27138 <entry role=
"func_table_entry"><para role=
"func_signature">
27140 <primary>pg_current_xact_id_if_assigned
</primary>
27142 <function>pg_current_xact_id_if_assigned
</function> ()
27143 <returnvalue>xid8
</returnvalue>
27146 Returns the current transaction's ID, or
<literal>NULL
</literal> if no
27147 ID is assigned yet. (It's best to use this variant if the transaction
27148 might otherwise be read-only, to avoid unnecessary consumption of an
27150 If executed in a subtransaction, this will return the top-level
27156 <entry role=
"func_table_entry"><para role=
"func_signature">
27158 <primary>pg_xact_status
</primary>
27160 <function>pg_xact_status
</function> (
<type>xid8
</type> )
27161 <returnvalue>text
</returnvalue>
27164 Reports the commit status of a recent transaction.
27165 The result is one of
<literal>in progress
</literal>,
27166 <literal>committed
</literal>, or
<literal>aborted
</literal>,
27167 provided that the transaction is recent enough that the system retains
27168 the commit status of that transaction.
27169 If it is old enough that no references to the transaction survive in
27170 the system and the commit status information has been discarded, the
27171 result is
<literal>NULL
</literal>.
27172 Applications might use this function, for example, to determine
27173 whether their transaction committed or aborted after the application
27174 and database server become disconnected while
27175 a
<literal>COMMIT
</literal> is in progress.
27176 Note that prepared transactions are reported as
<literal>in
27177 progress
</literal>; applications must check
<link
27178 linkend=
"view-pg-prepared-xacts"><structname>pg_prepared_xacts
</structname></link>
27179 if they need to determine whether a transaction ID belongs to a
27180 prepared transaction.
27185 <entry role=
"func_table_entry"><para role=
"func_signature">
27187 <primary>pg_current_snapshot
</primary>
27189 <function>pg_current_snapshot
</function> ()
27190 <returnvalue>pg_snapshot
</returnvalue>
27193 Returns a current
<firstterm>snapshot
</firstterm>, a data structure
27194 showing which transaction IDs are now in-progress.
27195 Only top-level transaction IDs are included in the snapshot;
27196 subtransaction IDs are not shown; see
<xref linkend=
"subxacts"/>
27202 <entry role=
"func_table_entry"><para role=
"func_signature">
27204 <primary>pg_snapshot_xip
</primary>
27206 <function>pg_snapshot_xip
</function> (
<type>pg_snapshot
</type> )
27207 <returnvalue>setof xid8
</returnvalue>
27210 Returns the set of in-progress transaction IDs contained in a snapshot.
27215 <entry role=
"func_table_entry"><para role=
"func_signature">
27217 <primary>pg_snapshot_xmax
</primary>
27219 <function>pg_snapshot_xmax
</function> (
<type>pg_snapshot
</type> )
27220 <returnvalue>xid8
</returnvalue>
27223 Returns the
<structfield>xmax
</structfield> of a snapshot.
27228 <entry role=
"func_table_entry"><para role=
"func_signature">
27230 <primary>pg_snapshot_xmin
</primary>
27232 <function>pg_snapshot_xmin
</function> (
<type>pg_snapshot
</type> )
27233 <returnvalue>xid8
</returnvalue>
27236 Returns the
<structfield>xmin
</structfield> of a snapshot.
27241 <entry role=
"func_table_entry"><para role=
"func_signature">
27243 <primary>pg_visible_in_snapshot
</primary>
27245 <function>pg_visible_in_snapshot
</function> (
<type>xid8
</type>,
<type>pg_snapshot
</type> )
27246 <returnvalue>boolean
</returnvalue>
27249 Is the given transaction ID
<firstterm>visible
</firstterm> according
27250 to this snapshot (that is, was it completed before the snapshot was
27251 taken)? Note that this function will not give the correct answer for
27252 a subtransaction ID (subxid); see
<xref linkend=
"subxacts"/> for
27261 The internal transaction ID type
<type>xid
</type> is
32 bits wide and
27262 wraps around every
4 billion transactions. However,
27263 the functions shown in
<xref linkend=
"functions-pg-snapshot"/> use a
27264 64-bit type
<type>xid8
</type> that does not wrap around during the life
27265 of an installation and can be converted to
<type>xid
</type> by casting if
27266 required; see
<xref linkend=
"transaction-id"/> for details.
27267 The data type
<type>pg_snapshot
</type> stores information about
27268 transaction ID visibility at a particular moment in time. Its components
27269 are described in
<xref linkend=
"functions-pg-snapshot-parts"/>.
27270 <type>pg_snapshot
</type>'s textual representation is
27271 <literal><replaceable>xmin
</replaceable>:
<replaceable>xmax
</replaceable>:
<replaceable>xip_list
</replaceable></literal>.
27272 For example
<literal>10:
20:
10,
14,
15</literal> means
27273 <literal>xmin=
10, xmax=
20, xip_list=
10,
14,
15</literal>.
27276 <table id=
"functions-pg-snapshot-parts">
27277 <title>Snapshot Components
</title>
27281 <entry>Name
</entry>
27282 <entry>Description
</entry>
27288 <entry><structfield>xmin
</structfield></entry>
27290 Lowest transaction ID that was still active. All transaction IDs
27291 less than
<structfield>xmin
</structfield> are either committed and visible,
27292 or rolled back and dead.
27297 <entry><structfield>xmax
</structfield></entry>
27299 One past the highest completed transaction ID. All transaction IDs
27300 greater than or equal to
<structfield>xmax
</structfield> had not yet
27301 completed as of the time of the snapshot, and thus are invisible.
27306 <entry><structfield>xip_list
</structfield></entry>
27308 Transactions in progress at the time of the snapshot. A transaction
27309 ID that is
<literal>xmin
<=
<replaceable>X
</replaceable> <
27310 xmax
</literal> and not in this list was already completed at the time
27311 of the snapshot, and thus is either visible or dead according to its
27312 commit status. This list does not include the transaction IDs of
27313 subtransactions (subxids).
27321 In releases of
<productname>PostgreSQL
</productname> before
13 there was
27322 no
<type>xid8
</type> type, so variants of these functions were provided
27323 that used
<type>bigint
</type> to represent a
64-bit XID, with a
27324 correspondingly distinct snapshot data type
<type>txid_snapshot
</type>.
27325 These older functions have
<literal>txid
</literal> in their names. They
27326 are still supported for backward compatibility, but may be removed from a
27327 future release. See
<xref linkend=
"functions-txid-snapshot"/>.
27330 <table id=
"functions-txid-snapshot">
27331 <title>Deprecated Transaction ID and Snapshot Information Functions
</title>
27335 <entry role=
"func_table_entry"><para role=
"func_signature">
27346 <entry role=
"func_table_entry"><para role=
"func_signature">
27348 <primary>age
</primary>
27350 <function>age
</function> (
<type>xid
</type> )
27351 <returnvalue>integer
</returnvalue>
27354 Returns the number of transactions between the supplied
27355 transaction id and the current transaction counter.
27360 <entry role=
"func_table_entry"><para role=
"func_signature">
27362 <primary>mxid_age
</primary>
27364 <function>mxid_age
</function> (
<type>xid
</type> )
27365 <returnvalue>integer
</returnvalue>
27368 Returns the number of multixacts IDs between the supplied
27369 multixact ID and the current multixacts counter.
27374 <entry role=
"func_table_entry"><para role=
"func_signature">
27376 <primary>txid_current
</primary>
27378 <function>txid_current
</function> ()
27379 <returnvalue>bigint
</returnvalue>
27382 See
<function>pg_current_xact_id()
</function>.
27387 <entry role=
"func_table_entry"><para role=
"func_signature">
27389 <primary>txid_current_if_assigned
</primary>
27391 <function>txid_current_if_assigned
</function> ()
27392 <returnvalue>bigint
</returnvalue>
27395 See
<function>pg_current_xact_id_if_assigned()
</function>.
27400 <entry role=
"func_table_entry"><para role=
"func_signature">
27402 <primary>txid_current_snapshot
</primary>
27404 <function>txid_current_snapshot
</function> ()
27405 <returnvalue>txid_snapshot
</returnvalue>
27408 See
<function>pg_current_snapshot()
</function>.
27413 <entry role=
"func_table_entry"><para role=
"func_signature">
27415 <primary>txid_snapshot_xip
</primary>
27417 <function>txid_snapshot_xip
</function> (
<type>txid_snapshot
</type> )
27418 <returnvalue>setof bigint
</returnvalue>
27421 See
<function>pg_snapshot_xip()
</function>.
27426 <entry role=
"func_table_entry"><para role=
"func_signature">
27428 <primary>txid_snapshot_xmax
</primary>
27430 <function>txid_snapshot_xmax
</function> (
<type>txid_snapshot
</type> )
27431 <returnvalue>bigint
</returnvalue>
27434 See
<function>pg_snapshot_xmax()
</function>.
27439 <entry role=
"func_table_entry"><para role=
"func_signature">
27441 <primary>txid_snapshot_xmin
</primary>
27443 <function>txid_snapshot_xmin
</function> (
<type>txid_snapshot
</type> )
27444 <returnvalue>bigint
</returnvalue>
27447 See
<function>pg_snapshot_xmin()
</function>.
27452 <entry role=
"func_table_entry"><para role=
"func_signature">
27454 <primary>txid_visible_in_snapshot
</primary>
27456 <function>txid_visible_in_snapshot
</function> (
<type>bigint
</type>,
<type>txid_snapshot
</type> )
27457 <returnvalue>boolean
</returnvalue>
27460 See
<function>pg_visible_in_snapshot()
</function>.
27465 <entry role=
"func_table_entry"><para role=
"func_signature">
27467 <primary>txid_status
</primary>
27469 <function>txid_status
</function> (
<type>bigint
</type> )
27470 <returnvalue>text
</returnvalue>
27473 See
<function>pg_xact_status()
</function>.
27482 <sect2 id=
"functions-info-commit-timestamp">
27483 <title>Committed Transaction Information Functions
</title>
27486 The functions shown in
<xref linkend=
"functions-commit-timestamp"/>
27487 provide information about when past transactions were committed.
27488 They only provide useful data when the
27489 <xref linkend=
"guc-track-commit-timestamp"/> configuration option is
27490 enabled, and only for transactions that were committed after it was
27491 enabled. Commit timestamp information is routinely removed during
27495 <table id=
"functions-commit-timestamp">
27496 <title>Committed Transaction Information Functions
</title>
27500 <entry role=
"func_table_entry"><para role=
"func_signature">
27511 <entry role=
"func_table_entry"><para role=
"func_signature">
27513 <primary>pg_xact_commit_timestamp
</primary>
27515 <function>pg_xact_commit_timestamp
</function> (
<type>xid
</type> )
27516 <returnvalue>timestamp with time zone
</returnvalue>
27519 Returns the commit timestamp of a transaction.
27524 <entry role=
"func_table_entry"><para role=
"func_signature">
27526 <primary>pg_xact_commit_timestamp_origin
</primary>
27528 <function>pg_xact_commit_timestamp_origin
</function> (
<type>xid
</type> )
27529 <returnvalue>record
</returnvalue>
27530 (
<parameter>timestamp
</parameter> <type>timestamp with time zone
</type>,
27531 <parameter>roident
</parameter> <type>oid
</type>)
27534 Returns the commit timestamp and replication origin of a transaction.
27539 <entry role=
"func_table_entry"><para role=
"func_signature">
27541 <primary>pg_last_committed_xact
</primary>
27543 <function>pg_last_committed_xact
</function> ()
27544 <returnvalue>record
</returnvalue>
27545 (
<parameter>xid
</parameter> <type>xid
</type>,
27546 <parameter>timestamp
</parameter> <type>timestamp with time zone
</type>,
27547 <parameter>roident
</parameter> <type>oid
</type> )
27550 Returns the transaction ID, commit timestamp and replication origin
27551 of the latest committed transaction.
27560 <sect2 id=
"functions-info-controldata">
27561 <title>Control Data Functions
</title>
27564 The functions shown in
<xref linkend=
"functions-controldata"/>
27565 print information initialized during
<command>initdb
</command>, such
27566 as the catalog version. They also show information about write-ahead
27567 logging and checkpoint processing. This information is cluster-wide,
27568 not specific to any one database. These functions provide most of the same
27569 information, from the same source, as the
27570 <xref linkend=
"app-pgcontroldata"/> application.
27573 <table id=
"functions-controldata">
27574 <title>Control Data Functions
</title>
27578 <entry role=
"func_table_entry"><para role=
"func_signature">
27589 <entry role=
"func_table_entry"><para role=
"func_signature">
27591 <primary>pg_control_checkpoint
</primary>
27593 <function>pg_control_checkpoint
</function> ()
27594 <returnvalue>record
</returnvalue>
27597 Returns information about current checkpoint state, as shown in
27598 <xref linkend=
"functions-pg-control-checkpoint"/>.
27603 <entry role=
"func_table_entry"><para role=
"func_signature">
27605 <primary>pg_control_system
</primary>
27607 <function>pg_control_system
</function> ()
27608 <returnvalue>record
</returnvalue>
27611 Returns information about current control file state, as shown in
27612 <xref linkend=
"functions-pg-control-system"/>.
27617 <entry role=
"func_table_entry"><para role=
"func_signature">
27619 <primary>pg_control_init
</primary>
27621 <function>pg_control_init
</function> ()
27622 <returnvalue>record
</returnvalue>
27625 Returns information about cluster initialization state, as shown in
27626 <xref linkend=
"functions-pg-control-init"/>.
27631 <entry role=
"func_table_entry"><para role=
"func_signature">
27633 <primary>pg_control_recovery
</primary>
27635 <function>pg_control_recovery
</function> ()
27636 <returnvalue>record
</returnvalue>
27639 Returns information about recovery state, as shown in
27640 <xref linkend=
"functions-pg-control-recovery"/>.
27647 <table id=
"functions-pg-control-checkpoint">
27648 <title><function>pg_control_checkpoint
</function> Output Columns
</title>
27652 <entry>Column Name
</entry>
27653 <entry>Data Type
</entry>
27660 <entry><structfield>checkpoint_lsn
</structfield></entry>
27661 <entry><type>pg_lsn
</type></entry>
27665 <entry><structfield>redo_lsn
</structfield></entry>
27666 <entry><type>pg_lsn
</type></entry>
27670 <entry><structfield>redo_wal_file
</structfield></entry>
27671 <entry><type>text
</type></entry>
27675 <entry><structfield>timeline_id
</structfield></entry>
27676 <entry><type>integer
</type></entry>
27680 <entry><structfield>prev_timeline_id
</structfield></entry>
27681 <entry><type>integer
</type></entry>
27685 <entry><structfield>full_page_writes
</structfield></entry>
27686 <entry><type>boolean
</type></entry>
27690 <entry><structfield>next_xid
</structfield></entry>
27691 <entry><type>text
</type></entry>
27695 <entry><structfield>next_oid
</structfield></entry>
27696 <entry><type>oid
</type></entry>
27700 <entry><structfield>next_multixact_id
</structfield></entry>
27701 <entry><type>xid
</type></entry>
27705 <entry><structfield>next_multi_offset
</structfield></entry>
27706 <entry><type>xid
</type></entry>
27710 <entry><structfield>oldest_xid
</structfield></entry>
27711 <entry><type>xid
</type></entry>
27715 <entry><structfield>oldest_xid_dbid
</structfield></entry>
27716 <entry><type>oid
</type></entry>
27720 <entry><structfield>oldest_active_xid
</structfield></entry>
27721 <entry><type>xid
</type></entry>
27725 <entry><structfield>oldest_multi_xid
</structfield></entry>
27726 <entry><type>xid
</type></entry>
27730 <entry><structfield>oldest_multi_dbid
</structfield></entry>
27731 <entry><type>oid
</type></entry>
27735 <entry><structfield>oldest_commit_ts_xid
</structfield></entry>
27736 <entry><type>xid
</type></entry>
27740 <entry><structfield>newest_commit_ts_xid
</structfield></entry>
27741 <entry><type>xid
</type></entry>
27745 <entry><structfield>checkpoint_time
</structfield></entry>
27746 <entry><type>timestamp with time zone
</type></entry>
27753 <table id=
"functions-pg-control-system">
27754 <title><function>pg_control_system
</function> Output Columns
</title>
27758 <entry>Column Name
</entry>
27759 <entry>Data Type
</entry>
27766 <entry><structfield>pg_control_version
</structfield></entry>
27767 <entry><type>integer
</type></entry>
27771 <entry><structfield>catalog_version_no
</structfield></entry>
27772 <entry><type>integer
</type></entry>
27776 <entry><structfield>system_identifier
</structfield></entry>
27777 <entry><type>bigint
</type></entry>
27781 <entry><structfield>pg_control_last_modified
</structfield></entry>
27782 <entry><type>timestamp with time zone
</type></entry>
27789 <table id=
"functions-pg-control-init">
27790 <title><function>pg_control_init
</function> Output Columns
</title>
27794 <entry>Column Name
</entry>
27795 <entry>Data Type
</entry>
27802 <entry><structfield>max_data_alignment
</structfield></entry>
27803 <entry><type>integer
</type></entry>
27807 <entry><structfield>database_block_size
</structfield></entry>
27808 <entry><type>integer
</type></entry>
27812 <entry><structfield>blocks_per_segment
</structfield></entry>
27813 <entry><type>integer
</type></entry>
27817 <entry><structfield>wal_block_size
</structfield></entry>
27818 <entry><type>integer
</type></entry>
27822 <entry><structfield>bytes_per_wal_segment
</structfield></entry>
27823 <entry><type>integer
</type></entry>
27827 <entry><structfield>max_identifier_length
</structfield></entry>
27828 <entry><type>integer
</type></entry>
27832 <entry><structfield>max_index_columns
</structfield></entry>
27833 <entry><type>integer
</type></entry>
27837 <entry><structfield>max_toast_chunk_size
</structfield></entry>
27838 <entry><type>integer
</type></entry>
27842 <entry><structfield>large_object_chunk_size
</structfield></entry>
27843 <entry><type>integer
</type></entry>
27847 <entry><structfield>float8_pass_by_value
</structfield></entry>
27848 <entry><type>boolean
</type></entry>
27852 <entry><structfield>data_page_checksum_version
</structfield></entry>
27853 <entry><type>integer
</type></entry>
27860 <table id=
"functions-pg-control-recovery">
27861 <title><function>pg_control_recovery
</function> Output Columns
</title>
27865 <entry>Column Name
</entry>
27866 <entry>Data Type
</entry>
27873 <entry><structfield>min_recovery_end_lsn
</structfield></entry>
27874 <entry><type>pg_lsn
</type></entry>
27878 <entry><structfield>min_recovery_end_timeline
</structfield></entry>
27879 <entry><type>integer
</type></entry>
27883 <entry><structfield>backup_start_lsn
</structfield></entry>
27884 <entry><type>pg_lsn
</type></entry>
27888 <entry><structfield>backup_end_lsn
</structfield></entry>
27889 <entry><type>pg_lsn
</type></entry>
27893 <entry><structfield>end_of_backup_record_required
</structfield></entry>
27894 <entry><type>boolean
</type></entry>
27903 <sect2 id=
"functions-info-version">
27904 <title>Version Information Functions
</title>
27907 The functions shown in
<xref linkend=
"functions-version"/>
27908 print version information.
27911 <table id=
"functions-version">
27912 <title>Version Information Functions
</title>
27916 <entry role=
"func_table_entry"><para role=
"func_signature">
27927 <entry role=
"func_table_entry"><para role=
"func_signature">
27929 <primary>version
</primary>
27931 <function>version
</function> ()
27932 <returnvalue>text
</returnvalue>
27935 Returns a string describing the
<productname>PostgreSQL
</productname>
27936 server's version. You can also get this information from
27937 <xref linkend=
"guc-server-version"/>, or for a machine-readable
27938 version use
<xref linkend=
"guc-server-version-num"/>. Software
27939 developers should use
<varname>server_version_num
</varname> (available
27940 since
8.2) or
<xref linkend=
"libpq-PQserverVersion"/> instead of
27941 parsing the text version.
27946 <entry role=
"func_table_entry"><para role=
"func_signature">
27948 <primary>unicode_version
</primary>
27950 <function>unicode_version
</function> ()
27951 <returnvalue>text
</returnvalue>
27954 Returns a string representing the version of Unicode used by
27955 <productname>PostgreSQL
</productname>.
27959 <entry role=
"func_table_entry"><para role=
"func_signature">
27961 <primary>icu_unicode_version
</primary>
27963 <function>icu_unicode_version
</function> ()
27964 <returnvalue>text
</returnvalue>
27967 Returns a string representing the version of Unicode used by ICU, if
27968 the server was built with ICU support; otherwise returns
27969 <literal>NULL
</literal> </para></entry>
27977 <sect2 id=
"functions-info-wal-summary">
27978 <title>WAL Summarization Information Functions
</title>
27981 The functions shown in
<xref linkend=
"functions-wal-summary"/>
27982 print information about the status of WAL summarization.
27983 See
<xref linkend=
"guc-summarize-wal" />.
27986 <table id=
"functions-wal-summary">
27987 <title>WAL Summarization Information Functions
</title>
27991 <entry role=
"func_table_entry"><para role=
"func_signature">
28002 <entry role=
"func_table_entry"><para role=
"func_signature">
28004 <primary>pg_available_wal_summaries
</primary>
28006 <function>pg_available_wal_summaries
</function> ()
28007 <returnvalue>setof record
</returnvalue>
28008 (
<parameter>tli
</parameter> <type>bigint
</type>,
28009 <parameter>start_lsn
</parameter> <type>pg_lsn
</type>,
28010 <parameter>end_lsn
</parameter> <type>pg_lsn
</type> )
28013 Returns information about the WAL summary files present in the
28014 data directory, under
<literal>pg_wal/summaries
</literal>.
28015 One row will be returned per WAL summary file. Each file summarizes
28016 WAL on the indicated TLI within the indicated LSN range. This function
28017 might be useful to determine whether enough WAL summaries are present
28018 on the server to take an incremental backup based on some prior
28019 backup whose start LSN is known.
28024 <entry role=
"func_table_entry"><para role=
"func_signature">
28026 <primary>pg_wal_summary_contents
</primary>
28028 <function>pg_wal_summary_contents
</function> (
<parameter>tli
</parameter> <type>bigint
</type>,
<parameter>start_lsn
</parameter> <type>pg_lsn
</type>,
<parameter>end_lsn
</parameter> <type>pg_lsn
</type> )
28029 <returnvalue>setof record
</returnvalue>
28030 (
<parameter>relfilenode
</parameter> <type>oid
</type>,
28031 <parameter>reltablespace
</parameter> <type>oid
</type>,
28032 <parameter>reldatabase
</parameter> <type>oid
</type>,
28033 <parameter>relforknumber
</parameter> <type>smallint
</type>,
28034 <parameter>relblocknumber
</parameter> <type>bigint
</type>,
28035 <parameter>is_limit_block
</parameter> <type>boolean
</type> )
28038 Returns one information about the contents of a single WAL summary file
28039 identified by TLI and starting and ending LSNs. Each row with
28040 <literal>is_limit_block
</literal> false indicates that the block
28041 identified by the remaining output columns was modified by at least
28042 one WAL record within the range of records summarized by this file.
28043 Each row with
<literal>is_limit_block
</literal> true indicates either
28044 that (a) the relation fork was truncated to the length given by
28045 <literal>relblocknumber
</literal> within the relevant range of WAL
28046 records or (b) that the relation fork was created or dropped within
28047 the relevant range of WAL records; in such cases,
28048 <literal>relblocknumber
</literal> will be zero.
28053 <entry role=
"func_table_entry"><para role=
"func_signature">
28055 <primary>pg_get_wal_summarizer_state
</primary>
28057 <function>pg_get_wal_summarizer_state
</function> ()
28058 <returnvalue>record
</returnvalue>
28059 (
<parameter>summarized_tli
</parameter> <type>bigint
</type>,
28060 <parameter>summarized_lsn
</parameter> <type>pg_lsn
</type>,
28061 <parameter>pending_lsn
</parameter> <type>pg_lsn
</type>,
28062 <parameter>summarizer_pid
</parameter> <type>int
</type> )
28065 Returns information about the progress of the WAL summarizer. If the
28066 WAL summarizer has never run since the instance was started, then
28067 <literal>summarized_tli
</literal> and
<literal>summarized_lsn
</literal>
28068 will be
<literal>0</literal> and
<literal>0/
0</literal> respectively;
28069 otherwise, they will be the TLI and ending LSN of the last WAL summary
28070 file written to disk. If the WAL summarizer is currently running,
28071 <literal>pending_lsn
</literal> will be the ending LSN of the last
28072 record that it has consumed, which must always be greater than or
28073 equal to
<literal>summarized_lsn
</literal>; if the WAL summarizer is
28074 not running, it will be equal to
<literal>summarized_lsn
</literal>.
28075 <literal>summarizer_pid
</literal> is the PID of the WAL summarizer
28076 process, if it is running, and otherwise NULL.
28079 As a special exception, the WAL summarizer will refuse to generate
28080 WAL summary files if run on WAL generated under
28081 <literal>wal_level=minimal
</literal>, since such summaries would be
28082 unsafe to use as the basis for an incremental backup. In this case,
28083 the fields above will continue to advance as if summaries were being
28084 generated, but nothing will be written to disk. Once the summarizer
28085 reaches WAL generated while
<literal>wal_level
</literal> was set
28086 to
<literal>replica
</literal> or higher, it will resume writing
28098 <sect1 id=
"functions-admin">
28099 <title>System Administration Functions
</title>
28102 The functions described in this section are used to control and
28103 monitor a
<productname>PostgreSQL
</productname> installation.
28106 <sect2 id=
"functions-admin-set">
28107 <title>Configuration Settings Functions
</title>
28110 <primary>SET
</primary>
28114 <primary>SHOW
</primary>
28118 <primary>configuration
</primary>
28119 <secondary sortas=
"server">of the server
</secondary>
28120 <tertiary>functions
</tertiary>
28124 <xref linkend=
"functions-admin-set-table"/> shows the functions
28125 available to query and alter run-time configuration parameters.
28128 <table id=
"functions-admin-set-table">
28129 <title>Configuration Settings Functions
</title>
28133 <entry role=
"func_table_entry"><para role=
"func_signature">
28147 <entry role=
"func_table_entry"><para role=
"func_signature">
28149 <primary>current_setting
</primary>
28151 <function>current_setting
</function> (
<parameter>setting_name
</parameter> <type>text
</type> <optional>,
<parameter>missing_ok
</parameter> <type>boolean
</type> </optional> )
28152 <returnvalue>text
</returnvalue>
28155 Returns the current value of the
28156 setting
<parameter>setting_name
</parameter>. If there is no such
28157 setting,
<function>current_setting
</function> throws an error
28158 unless
<parameter>missing_ok
</parameter> is supplied and
28159 is
<literal>true
</literal> (in which case NULL is returned).
28160 This function corresponds to
28161 the
<acronym>SQL
</acronym> command
<xref linkend=
"sql-show"/>.
28164 <literal>current_setting('datestyle')
</literal>
28165 <returnvalue>ISO, MDY
</returnvalue>
28170 <entry role=
"func_table_entry"><para role=
"func_signature">
28172 <primary>set_config
</primary>
28174 <function>set_config
</function> (
28175 <parameter>setting_name
</parameter> <type>text
</type>,
28176 <parameter>new_value
</parameter> <type>text
</type>,
28177 <parameter>is_local
</parameter> <type>boolean
</type> )
28178 <returnvalue>text
</returnvalue>
28181 Sets the parameter
<parameter>setting_name
</parameter>
28182 to
<parameter>new_value
</parameter>, and returns that value.
28183 If
<parameter>is_local
</parameter> is
<literal>true
</literal>, the new
28184 value will only apply during the current transaction. If you want the
28185 new value to apply for the rest of the current session,
28186 use
<literal>false
</literal> instead. This function corresponds to
28187 the SQL command
<xref linkend=
"sql-set"/>.
28190 <literal>set_config('log_statement_stats', 'off', false)
</literal>
28191 <returnvalue>off
</returnvalue>
28200 <sect2 id=
"functions-admin-signal">
28201 <title>Server Signaling Functions
</title>
28204 <primary>signal
</primary>
28205 <secondary sortas=
"backend">backend processes
</secondary>
28209 The functions shown in
<xref
28210 linkend=
"functions-admin-signal-table"/> send control signals to
28211 other server processes. Use of these functions is restricted to
28212 superusers by default but access may be granted to others using
28213 <command>GRANT
</command>, with noted exceptions.
28217 Each of these functions returns
<literal>true
</literal> if
28218 the signal was successfully sent and
<literal>false
</literal>
28219 if sending the signal failed.
28222 <table id=
"functions-admin-signal-table">
28223 <title>Server Signaling Functions
</title>
28227 <entry role=
"func_table_entry"><para role=
"func_signature">
28238 <entry role=
"func_table_entry"><para role=
"func_signature">
28240 <primary>pg_cancel_backend
</primary>
28242 <function>pg_cancel_backend
</function> (
<parameter>pid
</parameter> <type>integer
</type> )
28243 <returnvalue>boolean
</returnvalue>
28246 Cancels the current query of the session whose backend process has the
28247 specified process ID. This is also allowed if the
28248 calling role is a member of the role whose backend is being canceled or
28249 the calling role has privileges of
<literal>pg_signal_backend
</literal>,
28250 however only superusers can cancel superuser backends.
28251 As an exception, roles with privileges of
28252 <literal>pg_signal_autovacuum_worker
</literal> are permitted to
28253 cancel autovacuum worker processes, which are otherwise considered
28254 superuser backends.
28259 <entry role=
"func_table_entry"><para role=
"func_signature">
28261 <primary>pg_log_backend_memory_contexts
</primary>
28263 <function>pg_log_backend_memory_contexts
</function> (
<parameter>pid
</parameter> <type>integer
</type> )
28264 <returnvalue>boolean
</returnvalue>
28267 Requests to log the memory contexts of the backend with the
28268 specified process ID. This function can send the request to
28269 backends and auxiliary processes except logger. These memory contexts
28271 <literal>LOG
</literal> message level. They will appear in
28272 the server log based on the log configuration set
28273 (see
<xref linkend=
"runtime-config-logging"/> for more information),
28274 but will not be sent to the client regardless of
28275 <xref linkend=
"guc-client-min-messages"/>.
28280 <entry role=
"func_table_entry"><para role=
"func_signature">
28282 <primary>pg_reload_conf
</primary>
28284 <function>pg_reload_conf
</function> ()
28285 <returnvalue>boolean
</returnvalue>
28288 Causes all processes of the
<productname>PostgreSQL
</productname>
28289 server to reload their configuration files. (This is initiated by
28290 sending a
<systemitem>SIGHUP
</systemitem> signal to the postmaster
28291 process, which in turn sends
<systemitem>SIGHUP
</systemitem> to each
28292 of its children.) You can use the
28293 <link linkend=
"view-pg-file-settings"><structname>pg_file_settings
</structname></link>,
28294 <link linkend=
"view-pg-hba-file-rules"><structname>pg_hba_file_rules
</structname></link> and
28295 <link linkend=
"view-pg-ident-file-mappings"><structname>pg_ident_file_mappings
</structname></link> views
28296 to check the configuration files for possible errors, before reloading.
28301 <entry role=
"func_table_entry"><para role=
"func_signature">
28303 <primary>pg_rotate_logfile
</primary>
28305 <function>pg_rotate_logfile
</function> ()
28306 <returnvalue>boolean
</returnvalue>
28309 Signals the log-file manager to switch to a new output file
28310 immediately. This works only when the built-in log collector is
28311 running, since otherwise there is no log-file manager subprocess.
28316 <entry role=
"func_table_entry"><para role=
"func_signature">
28318 <primary>pg_terminate_backend
</primary>
28320 <function>pg_terminate_backend
</function> (
<parameter>pid
</parameter> <type>integer
</type>,
<parameter>timeout
</parameter> <type>bigint
</type> <literal>DEFAULT
</literal> <literal>0</literal> )
28321 <returnvalue>boolean
</returnvalue>
28324 Terminates the session whose backend process has the
28325 specified process ID. This is also allowed if the calling role
28326 is a member of the role whose backend is being terminated or the
28327 calling role has privileges of
<literal>pg_signal_backend
</literal>,
28328 however only superusers can terminate superuser backends.
28329 As an exception, roles with privileges of
28330 <literal>pg_signal_autovacuum_worker
</literal> are permitted to
28331 terminate autovacuum worker processes, which are otherwise considered
28332 superuser backends.
28335 If
<parameter>timeout
</parameter> is not specified or zero, this
28336 function returns
<literal>true
</literal> whether the process actually
28337 terminates or not, indicating only that the sending of the signal was
28338 successful. If the
<parameter>timeout
</parameter> is specified (in
28339 milliseconds) and greater than zero, the function waits until the
28340 process is actually terminated or until the given time has passed. If
28341 the process is terminated, the function
28342 returns
<literal>true
</literal>. On timeout, a warning is emitted and
28343 <literal>false
</literal> is returned.
28351 <function>pg_cancel_backend
</function> and
<function>pg_terminate_backend
</function>
28352 send signals (
<systemitem>SIGINT
</systemitem> or
<systemitem>SIGTERM
</systemitem>
28353 respectively) to backend processes identified by process ID.
28354 The process ID of an active backend can be found from
28355 the
<structfield>pid
</structfield> column of the
28356 <structname>pg_stat_activity
</structname> view, or by listing the
28357 <command>postgres
</command> processes on the server (using
28358 <application>ps
</application> on Unix or the
<application>Task
28359 Manager
</application> on
<productname>Windows
</productname>).
28360 The role of an active backend can be found from the
28361 <structfield>usename
</structfield> column of the
28362 <structname>pg_stat_activity
</structname> view.
28366 <function>pg_log_backend_memory_contexts
</function> can be used
28367 to log the memory contexts of a backend process. For example:
28369 postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid());
28370 pg_log_backend_memory_contexts
28371 --------------------------------
28375 One message for each memory context will be logged. For example:
28377 LOG: logging memory contexts of PID
10377
28378 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid());
28379 LOG: level:
0; TopMemoryContext:
80800 total in
6 blocks;
14432 free (
5 chunks);
66368 used
28380 LOG: level:
1; pgstat TabStatusArray lookup hash table:
8192 total in
1 blocks;
1408 free (
0 chunks);
6784 used
28381 LOG: level:
1; TopTransactionContext:
8192 total in
1 blocks;
7720 free (
1 chunks);
472 used
28382 LOG: level:
1; RowDescriptionContext:
8192 total in
1 blocks;
6880 free (
0 chunks);
1312 used
28383 LOG: level:
1; MessageContext:
16384 total in
2 blocks;
5152 free (
0 chunks);
11232 used
28384 LOG: level:
1; Operator class cache:
8192 total in
1 blocks;
512 free (
0 chunks);
7680 used
28385 LOG: level:
1; smgr relation table:
16384 total in
2 blocks;
4544 free (
3 chunks);
11840 used
28386 LOG: level:
1; TransactionAbortContext:
32768 total in
1 blocks;
32504 free (
0 chunks);
264 used
28388 LOG: level:
1; ErrorContext:
8192 total in
1 blocks;
7928 free (
3 chunks);
264 used
28389 LOG: Grand total:
1651920 bytes in
201 blocks;
622360 free (
88 chunks);
1029560 used
28391 If there are more than
100 child contexts under the same parent, the first
28392 100 child contexts are logged, along with a summary of the remaining contexts.
28393 Note that frequent calls to this function could incur significant overhead,
28394 because it may generate a large number of log messages.
28399 <sect2 id=
"functions-admin-backup">
28400 <title>Backup Control Functions
</title>
28403 <primary>backup
</primary>
28407 The functions shown in
<xref
28408 linkend=
"functions-admin-backup-table"/> assist in making on-line backups.
28409 These functions cannot be executed during recovery (except
28410 <function>pg_backup_start
</function>,
28411 <function>pg_backup_stop
</function>,
28412 and
<function>pg_wal_lsn_diff
</function>).
28416 For details about proper usage of these functions, see
28417 <xref linkend=
"continuous-archiving"/>.
28420 <table id=
"functions-admin-backup-table">
28421 <title>Backup Control Functions
</title>
28425 <entry role=
"func_table_entry"><para role=
"func_signature">
28436 <entry role=
"func_table_entry"><para role=
"func_signature">
28438 <primary>pg_create_restore_point
</primary>
28440 <function>pg_create_restore_point
</function> (
<parameter>name
</parameter> <type>text
</type> )
28441 <returnvalue>pg_lsn
</returnvalue>
28444 Creates a named marker record in the write-ahead log that can later be
28445 used as a recovery target, and returns the corresponding write-ahead
28446 log location. The given name can then be used with
28447 <xref linkend=
"guc-recovery-target-name"/> to specify the point up to
28448 which recovery will proceed. Avoid creating multiple restore points
28449 with the same name, since recovery will stop at the first one whose
28450 name matches the recovery target.
28453 This function is restricted to superusers by default, but other users
28454 can be granted EXECUTE to run the function.
28459 <entry role=
"func_table_entry"><para role=
"func_signature">
28461 <primary>pg_current_wal_flush_lsn
</primary>
28463 <function>pg_current_wal_flush_lsn
</function> ()
28464 <returnvalue>pg_lsn
</returnvalue>
28467 Returns the current write-ahead log flush location (see notes below).
28472 <entry role=
"func_table_entry"><para role=
"func_signature">
28474 <primary>pg_current_wal_insert_lsn
</primary>
28476 <function>pg_current_wal_insert_lsn
</function> ()
28477 <returnvalue>pg_lsn
</returnvalue>
28480 Returns the current write-ahead log insert location (see notes below).
28485 <entry role=
"func_table_entry"><para role=
"func_signature">
28487 <primary>pg_current_wal_lsn
</primary>
28489 <function>pg_current_wal_lsn
</function> ()
28490 <returnvalue>pg_lsn
</returnvalue>
28493 Returns the current write-ahead log write location (see notes below).
28498 <entry role=
"func_table_entry"><para role=
"func_signature">
28500 <primary>pg_backup_start
</primary>
28502 <function>pg_backup_start
</function> (
28503 <parameter>label
</parameter> <type>text
</type>
28504 <optional>,
<parameter>fast
</parameter> <type>boolean
</type>
28506 <returnvalue>pg_lsn
</returnvalue>
28509 Prepares the server to begin an on-line backup. The only required
28510 parameter is an arbitrary user-defined label for the backup.
28511 (Typically this would be the name under which the backup dump file
28513 If the optional second parameter is given as
<literal>true
</literal>,
28514 it specifies executing
<function>pg_backup_start
</function> as quickly
28515 as possible. This forces an immediate checkpoint which will cause a
28516 spike in I/O operations, slowing any concurrently executing queries.
28519 This function is restricted to superusers by default, but other users
28520 can be granted EXECUTE to run the function.
28525 <entry role=
"func_table_entry"><para role=
"func_signature">
28527 <primary>pg_backup_stop
</primary>
28529 <function>pg_backup_stop
</function> (
28530 <optional><parameter>wait_for_archive
</parameter> <type>boolean
</type>
28532 <returnvalue>record
</returnvalue>
28533 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
28534 <parameter>labelfile
</parameter> <type>text
</type>,
28535 <parameter>spcmapfile
</parameter> <type>text
</type> )
28538 Finishes performing an on-line backup. The desired contents of the
28539 backup label file and the tablespace map file are returned as part of
28540 the result of the function and must be written to files in the
28541 backup area. These files must not be written to the live data directory
28542 (doing so will cause PostgreSQL to fail to restart in the event of a
28546 There is an optional parameter of type
<type>boolean
</type>.
28547 If false, the function will return immediately after the backup is
28548 completed, without waiting for WAL to be archived. This behavior is
28549 only useful with backup software that independently monitors WAL
28550 archiving. Otherwise, WAL required to make the backup consistent might
28551 be missing and make the backup useless. By default or when this
28552 parameter is true,
<function>pg_backup_stop
</function> will wait for
28553 WAL to be archived when archiving is enabled. (On a standby, this
28554 means that it will wait only when
<varname>archive_mode
</varname> =
28555 <literal>always
</literal>. If write activity on the primary is low,
28556 it may be useful to run
<function>pg_switch_wal
</function> on the
28557 primary in order to trigger an immediate segment switch.)
28560 When executed on a primary, this function also creates a backup
28561 history file in the write-ahead log archive area. The history file
28562 includes the label given to
<function>pg_backup_start
</function>, the
28563 starting and ending write-ahead log locations for the backup, and the
28564 starting and ending times of the backup. After recording the ending
28565 location, the current write-ahead log insertion point is automatically
28566 advanced to the next write-ahead log file, so that the ending
28567 write-ahead log file can be archived immediately to complete the
28571 The result of the function is a single record.
28572 The
<parameter>lsn
</parameter> column holds the backup's ending
28573 write-ahead log location (which again can be ignored). The second
28574 column returns the contents of the backup label file, and the third
28575 column returns the contents of the tablespace map file. These must be
28576 stored as part of the backup and are required as part of the restore
28580 This function is restricted to superusers by default, but other users
28581 can be granted EXECUTE to run the function.
28586 <entry role=
"func_table_entry"><para role=
"func_signature">
28588 <primary>pg_switch_wal
</primary>
28590 <function>pg_switch_wal
</function> ()
28591 <returnvalue>pg_lsn
</returnvalue>
28594 Forces the server to switch to a new write-ahead log file, which
28595 allows the current file to be archived (assuming you are using
28596 continuous archiving). The result is the ending write-ahead log
28597 location plus
1 within the just-completed write-ahead log file. If
28598 there has been no write-ahead log activity since the last write-ahead
28599 log switch,
<function>pg_switch_wal
</function> does nothing and
28600 returns the start location of the write-ahead log file currently in
28604 This function is restricted to superusers by default, but other users
28605 can be granted EXECUTE to run the function.
28610 <entry role=
"func_table_entry"><para role=
"func_signature">
28612 <primary>pg_walfile_name
</primary>
28614 <function>pg_walfile_name
</function> (
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
28615 <returnvalue>text
</returnvalue>
28618 Converts a write-ahead log location to the name of the WAL file
28619 holding that location.
28624 <entry role=
"func_table_entry"><para role=
"func_signature">
28626 <primary>pg_walfile_name_offset
</primary>
28628 <function>pg_walfile_name_offset
</function> (
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
28629 <returnvalue>record
</returnvalue>
28630 (
<parameter>file_name
</parameter> <type>text
</type>,
28631 <parameter>file_offset
</parameter> <type>integer
</type> )
28634 Converts a write-ahead log location to a WAL file name and byte offset
28640 <entry role=
"func_table_entry"><para role=
"func_signature">
28642 <primary>pg_split_walfile_name
</primary>
28644 <function>pg_split_walfile_name
</function> (
<parameter>file_name
</parameter> <type>text
</type> )
28645 <returnvalue>record
</returnvalue>
28646 (
<parameter>segment_number
</parameter> <type>numeric
</type>,
28647 <parameter>timeline_id
</parameter> <type>bigint
</type> )
28650 Extracts the sequence number and timeline ID from a WAL file
28656 <entry role=
"func_table_entry"><para role=
"func_signature">
28658 <primary>pg_wal_lsn_diff
</primary>
28660 <function>pg_wal_lsn_diff
</function> (
<parameter>lsn1
</parameter> <type>pg_lsn
</type>,
<parameter>lsn2
</parameter> <type>pg_lsn
</type> )
28661 <returnvalue>numeric
</returnvalue>
28664 Calculates the difference in bytes (
<parameter>lsn1
</parameter> -
<parameter>lsn2
</parameter>) between two write-ahead log
28665 locations. This can be used
28666 with
<structname>pg_stat_replication
</structname> or some of the
28667 functions shown in
<xref linkend=
"functions-admin-backup-table"/> to
28668 get the replication lag.
28676 <function>pg_current_wal_lsn
</function> displays the current write-ahead
28677 log write location in the same format used by the above functions.
28678 Similarly,
<function>pg_current_wal_insert_lsn
</function> displays the
28679 current write-ahead log insertion location
28680 and
<function>pg_current_wal_flush_lsn
</function> displays the current
28681 write-ahead log flush location. The insertion location is
28682 the
<quote>logical
</quote> end of the write-ahead log at any instant,
28683 while the write location is the end of what has actually been written out
28684 from the server's internal buffers, and the flush location is the last
28685 location known to be written to durable storage. The write location is the
28686 end of what can be examined from outside the server, and is usually what
28687 you want if you are interested in archiving partially-complete write-ahead
28688 log files. The insertion and flush locations are made available primarily
28689 for server debugging purposes. These are all read-only operations and do
28690 not require superuser permissions.
28694 You can use
<function>pg_walfile_name_offset
</function> to extract the
28695 corresponding write-ahead log file name and byte offset from
28696 a
<type>pg_lsn
</type> value. For example:
28698 postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn);
28699 file_name | file_offset
28700 --------------------------+-------------
28701 00000001000000000000000D |
4039624
28704 Similarly,
<function>pg_walfile_name
</function> extracts just the write-ahead log file name.
28708 <function>pg_split_walfile_name
</function> is useful to compute a
28709 <acronym>LSN
</acronym> from a file offset and WAL file name, for example:
28711 postgres=# \set file_name '
000000010000000100C000AB'
28712 postgres=# \set offset
256
28713 postgres=# SELECT '
0/
0'::pg_lsn + pd.segment_number * ps.setting::int + :offset AS lsn
28714 FROM pg_split_walfile_name(:'file_name') pd,
28715 pg_show_all_settings() ps
28716 WHERE ps.name = 'wal_segment_size';
28726 <sect2 id=
"functions-recovery-control">
28727 <title>Recovery Control Functions
</title>
28730 The functions shown in
<xref
28731 linkend=
"functions-recovery-info-table"/> provide information
28732 about the current status of a standby server.
28733 These functions may be executed both during recovery and in normal running.
28736 <table id=
"functions-recovery-info-table">
28737 <title>Recovery Information Functions
</title>
28741 <entry role=
"func_table_entry"><para role=
"func_signature">
28752 <entry role=
"func_table_entry"><para role=
"func_signature">
28754 <primary>pg_is_in_recovery
</primary>
28756 <function>pg_is_in_recovery
</function> ()
28757 <returnvalue>boolean
</returnvalue>
28760 Returns true if recovery is still in progress.
28765 <entry role=
"func_table_entry"><para role=
"func_signature">
28767 <primary>pg_last_wal_receive_lsn
</primary>
28769 <function>pg_last_wal_receive_lsn
</function> ()
28770 <returnvalue>pg_lsn
</returnvalue>
28773 Returns the last write-ahead log location that has been received and
28774 synced to disk by streaming replication. While streaming replication
28775 is in progress this will increase monotonically. If recovery has
28776 completed then this will remain static at the location of the last WAL
28777 record received and synced to disk during recovery. If streaming
28778 replication is disabled, or if it has not yet started, the function
28779 returns
<literal>NULL
</literal>.
28784 <entry role=
"func_table_entry"><para role=
"func_signature">
28786 <primary>pg_last_wal_replay_lsn
</primary>
28788 <function>pg_last_wal_replay_lsn
</function> ()
28789 <returnvalue>pg_lsn
</returnvalue>
28792 Returns the last write-ahead log location that has been replayed
28793 during recovery. If recovery is still in progress this will increase
28794 monotonically. If recovery has completed then this will remain
28795 static at the location of the last WAL record applied during recovery.
28796 When the server has been started normally without recovery, the
28797 function returns
<literal>NULL
</literal>.
28802 <entry role=
"func_table_entry"><para role=
"func_signature">
28804 <primary>pg_last_xact_replay_timestamp
</primary>
28806 <function>pg_last_xact_replay_timestamp
</function> ()
28807 <returnvalue>timestamp with time zone
</returnvalue>
28810 Returns the time stamp of the last transaction replayed during
28811 recovery. This is the time at which the commit or abort WAL record
28812 for that transaction was generated on the primary. If no transactions
28813 have been replayed during recovery, the function
28814 returns
<literal>NULL
</literal>. Otherwise, if recovery is still in
28815 progress this will increase monotonically. If recovery has completed
28816 then this will remain static at the time of the last transaction
28817 applied during recovery. When the server has been started normally
28818 without recovery, the function returns
<literal>NULL
</literal>.
28823 <entry role=
"func_table_entry"><para role=
"func_signature">
28825 <primary>pg_get_wal_resource_managers
</primary>
28827 <function>pg_get_wal_resource_managers
</function> ()
28828 <returnvalue>setof record
</returnvalue>
28829 (
<parameter>rm_id
</parameter> <type>integer
</type>,
28830 <parameter>rm_name
</parameter> <type>text
</type>,
28831 <parameter>rm_builtin
</parameter> <type>boolean
</type> )
28834 Returns the currently-loaded WAL resource managers in the system. The
28835 column
<parameter>rm_builtin
</parameter> indicates whether it's a
28836 built-in resource manager, or a custom resource manager loaded by an
28845 The functions shown in
<xref
28846 linkend=
"functions-recovery-control-table"/> control the progress of recovery.
28847 These functions may be executed only during recovery.
28850 <table id=
"functions-recovery-control-table">
28851 <title>Recovery Control Functions
</title>
28855 <entry role=
"func_table_entry"><para role=
"func_signature">
28866 <entry role=
"func_table_entry"><para role=
"func_signature">
28868 <primary>pg_is_wal_replay_paused
</primary>
28870 <function>pg_is_wal_replay_paused
</function> ()
28871 <returnvalue>boolean
</returnvalue>
28874 Returns true if recovery pause is requested.
28879 <entry role=
"func_table_entry"><para role=
"func_signature">
28881 <primary>pg_get_wal_replay_pause_state
</primary>
28883 <function>pg_get_wal_replay_pause_state
</function> ()
28884 <returnvalue>text
</returnvalue>
28887 Returns recovery pause state. The return values are
<literal>
28888 not paused
</literal> if pause is not requested,
<literal>
28889 pause requested
</literal> if pause is requested but recovery is
28890 not yet paused, and
<literal>paused
</literal> if the recovery is
28896 <entry role=
"func_table_entry"><para role=
"func_signature">
28898 <primary>pg_promote
</primary>
28900 <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> )
28901 <returnvalue>boolean
</returnvalue>
28904 Promotes a standby server to primary status.
28905 With
<parameter>wait
</parameter> set to
<literal>true
</literal> (the
28906 default), the function waits until promotion is completed
28907 or
<parameter>wait_seconds
</parameter> seconds have passed, and
28908 returns
<literal>true
</literal> if promotion is successful
28909 and
<literal>false
</literal> otherwise.
28910 If
<parameter>wait
</parameter> is set to
<literal>false
</literal>, the
28911 function returns
<literal>true
</literal> immediately after sending a
28912 <literal>SIGUSR1
</literal> signal to the postmaster to trigger
28916 This function is restricted to superusers by default, but other users
28917 can be granted EXECUTE to run the function.
28922 <entry role=
"func_table_entry"><para role=
"func_signature">
28924 <primary>pg_wal_replay_pause
</primary>
28926 <function>pg_wal_replay_pause
</function> ()
28927 <returnvalue>void
</returnvalue>
28930 Request to pause recovery. A request doesn't mean that recovery stops
28931 right away. If you want a guarantee that recovery is actually paused,
28932 you need to check for the recovery pause state returned by
28933 <function>pg_get_wal_replay_pause_state()
</function>. Note that
28934 <function>pg_is_wal_replay_paused()
</function> returns whether a request
28935 is made. While recovery is paused, no further database changes are applied.
28936 If hot standby is active, all new queries will see the same consistent
28937 snapshot of the database, and no further query conflicts will be generated
28938 until recovery is resumed.
28941 This function is restricted to superusers by default, but other users
28942 can be granted EXECUTE to run the function.
28947 <entry role=
"func_table_entry"><para role=
"func_signature">
28949 <primary>pg_wal_replay_resume
</primary>
28951 <function>pg_wal_replay_resume
</function> ()
28952 <returnvalue>void
</returnvalue>
28955 Restarts recovery if it was paused.
28958 This function is restricted to superusers by default, but other users
28959 can be granted EXECUTE to run the function.
28967 <function>pg_wal_replay_pause
</function> and
28968 <function>pg_wal_replay_resume
</function> cannot be executed while
28969 a promotion is ongoing. If a promotion is triggered while recovery
28970 is paused, the paused state ends and promotion continues.
28974 If streaming replication is disabled, the paused state may continue
28975 indefinitely without a problem. If streaming replication is in
28976 progress then WAL records will continue to be received, which will
28977 eventually fill available disk space, depending upon the duration of
28978 the pause, the rate of WAL generation and available disk space.
28982 The procedure shown in
<xref linkend=
"recovery-synchronization-procedure-table"/>
28983 can be executed only during recovery.
28986 <table id=
"recovery-synchronization-procedure-table">
28987 <title>Recovery Synchronization Procedure
</title>
28991 <entry role=
"func_table_entry"><para role=
"func_signature">
29002 <entry role=
"func_table_entry"><para role=
"func_signature">
29004 <primary>pg_wal_replay_wait
</primary>
29006 <function>pg_wal_replay_wait
</function> (
29007 <parameter>target_lsn
</parameter> <type>pg_lsn
</type>,
29008 <parameter>timeout
</parameter> <type>bigint
</type> <literal>DEFAULT
</literal> <literal>0</literal>)
29009 <returnvalue>void
</returnvalue>
29012 Waits until recovery replays
<literal>target_lsn
</literal>.
29013 If no
<parameter>timeout
</parameter> is specified or it is set to
29014 zero, this procedure waits indefinitely for the
29015 <literal>target_lsn
</literal>. If the
<parameter>timeout
</parameter>
29016 is specified (in milliseconds) and is greater than zero, the
29017 procedure waits until
<literal>target_lsn
</literal> is reached or
29018 the specified
<parameter>timeout
</parameter> has elapsed.
29019 On timeout, or if the server is promoted before
29020 <literal>target_lsn
</literal> is reached, an error is emitted.
29028 <function>pg_wal_replay_wait
</function> waits till
29029 <parameter>target_lsn
</parameter> to be replayed on standby.
29030 That is, after this function execution, the value returned by
29031 <function>pg_last_wal_replay_lsn
</function> should be greater or equal
29032 to the
<parameter>target_lsn
</parameter> value. This is useful to achieve
29033 read-your-writes-consistency, while using async replica for reads and
29034 primary for writes. In that case
<acronym>lsn
</acronym> of the last
29035 modification should be stored on the client application side or the
29036 connection pooler side.
29040 <function>pg_wal_replay_wait
</function> should be called on standby.
29041 If a user calls
<function>pg_wal_replay_wait
</function> on primary, it
29042 will error out. However, if
<function>pg_wal_replay_wait
</function> is
29043 called on primary promoted from standby and
<literal>target_lsn
</literal>
29044 was already replayed, then
<function>pg_wal_replay_wait
</function> just
29049 You can use
<function>pg_wal_replay_wait
</function> to wait for
29050 the
<type>pg_lsn
</type> value. For example, an application could update
29051 the
<literal>movie
</literal> table and get the
<acronym>lsn
</acronym> after
29052 changes just made. This example uses
<function>pg_current_wal_insert_lsn
</function>
29053 on primary server to get the
<acronym>lsn
</acronym> given that
29054 <varname>synchronous_commit
</varname> could be set to
29055 <literal>off
</literal>.
29058 postgres=# UPDATE movie SET genre = 'Dramatic' WHERE genre = 'Drama';
29060 postgres=# SELECT pg_current_wal_insert_lsn();
29061 pg_current_wal_insert_lsn
29062 --------------------
29067 Then an application could run
<function>pg_wal_replay_wait
</function>
29068 with the
<acronym>lsn
</acronym> obtained from primary. After that the
29069 changes made on primary should be guaranteed to be visible on replica.
29072 postgres=# CALL pg_wal_replay_wait('
0/
306EE20');
29074 postgres=# SELECT * FROM movie WHERE genre = 'Drama';
29080 It may also happen that target
<acronym>lsn
</acronym> is not achieved
29081 within the timeout. In that case the error is thrown.
29084 postgres=# CALL pg_wal_replay_wait('
0/
306EE20',
100);
29085 ERROR: timed out while waiting for target LSN
0/
306EE20 to be replayed; current replay LSN
0/
306EA60
29091 <function>pg_wal_replay_wait
</function> can't be used within
29092 a transaction with an isolation level higher than
29093 <literal>READ COMMITTED
</literal>, another procedure, or a function.
29094 All the cases above imply holding a snapshot, which could prevent
29095 WAL records from replaying (see
<xref linkend=
"hot-standby-conflict"/>)
29096 and cause an indirect deadlock.
29101 postgres=*# CALL pg_wal_replay_wait('
0/
306EE20');
29102 ERROR: pg_wal_replay_wait() must be only called without an active or registered snapshot
29103 DETAIL: Make sure pg_wal_replay_wait() isn't called within a transaction with an isolation level higher than READ COMMITTED, another procedure, or a function.
29109 <sect2 id=
"functions-snapshot-synchronization">
29110 <title>Snapshot Synchronization Functions
</title>
29113 <productname>PostgreSQL
</productname> allows database sessions to synchronize their
29114 snapshots. A
<firstterm>snapshot
</firstterm> determines which data is visible to the
29115 transaction that is using the snapshot. Synchronized snapshots are
29116 necessary when two or more sessions need to see identical content in the
29117 database. If two sessions just start their transactions independently,
29118 there is always a possibility that some third transaction commits
29119 between the executions of the two
<command>START TRANSACTION
</command> commands,
29120 so that one session sees the effects of that transaction and the other
29125 To solve this problem,
<productname>PostgreSQL
</productname> allows a transaction to
29126 <firstterm>export
</firstterm> the snapshot it is using. As long as the exporting
29127 transaction remains open, other transactions can
<firstterm>import
</firstterm> its
29128 snapshot, and thereby be guaranteed that they see exactly the same view
29129 of the database that the first transaction sees. But note that any
29130 database changes made by any one of these transactions remain invisible
29131 to the other transactions, as is usual for changes made by uncommitted
29132 transactions. So the transactions are synchronized with respect to
29133 pre-existing data, but act normally for changes they make themselves.
29137 Snapshots are exported with the
<function>pg_export_snapshot
</function> function,
29138 shown in
<xref linkend=
"functions-snapshot-synchronization-table"/>, and
29139 imported with the
<xref linkend=
"sql-set-transaction"/> command.
29142 <table id=
"functions-snapshot-synchronization-table">
29143 <title>Snapshot Synchronization Functions
</title>
29147 <entry role=
"func_table_entry"><para role=
"func_signature">
29158 <entry role=
"func_table_entry"><para role=
"func_signature">
29160 <primary>pg_export_snapshot
</primary>
29162 <function>pg_export_snapshot
</function> ()
29163 <returnvalue>text
</returnvalue>
29166 Saves the transaction's current snapshot and returns
29167 a
<type>text
</type> string identifying the snapshot. This string must
29168 be passed (outside the database) to clients that want to import the
29169 snapshot. The snapshot is available for import only until the end of
29170 the transaction that exported it.
29173 A transaction can export more than one snapshot, if needed. Note that
29174 doing so is only useful in
<literal>READ COMMITTED
</literal>
29175 transactions, since in
<literal>REPEATABLE READ
</literal> and higher
29176 isolation levels, transactions use the same snapshot throughout their
29177 lifetime. Once a transaction has exported any snapshots, it cannot be
29178 prepared with
<xref linkend=
"sql-prepare-transaction"/>.
29182 <entry role=
"func_table_entry"><para role=
"func_signature">
29184 <primary>pg_log_standby_snapshot
</primary>
29186 <function>pg_log_standby_snapshot
</function> ()
29187 <returnvalue>pg_lsn
</returnvalue>
29190 Take a snapshot of running transactions and write it to WAL, without
29191 having to wait for bgwriter or checkpointer to log one. This is useful
29192 for logical decoding on standby, as logical slot creation has to wait
29193 until such a record is replayed on the standby.
29202 <sect2 id=
"functions-replication">
29203 <title>Replication Management Functions
</title>
29206 The functions shown
29207 in
<xref linkend=
"functions-replication-table"/> are for
29208 controlling and interacting with replication features.
29209 See
<xref linkend=
"streaming-replication"/>,
29210 <xref linkend=
"streaming-replication-slots"/>, and
29211 <xref linkend=
"replication-origins"/>
29212 for information about the underlying features.
29213 Use of functions for replication origin is only allowed to the
29214 superuser by default, but may be allowed to other users by using the
29215 <literal>GRANT
</literal> command.
29216 Use of functions for replication slots is restricted to superusers
29217 and users having
<literal>REPLICATION
</literal> privilege.
29221 Many of these functions have equivalent commands in the replication
29222 protocol; see
<xref linkend=
"protocol-replication"/>.
29226 The functions described in
29227 <xref linkend=
"functions-admin-backup"/>,
29228 <xref linkend=
"functions-recovery-control"/>, and
29229 <xref linkend=
"functions-snapshot-synchronization"/>
29230 are also relevant for replication.
29233 <table id=
"functions-replication-table">
29234 <title>Replication Management Functions
</title>
29238 <entry role=
"func_table_entry"><para role=
"func_signature">
29249 <entry role=
"func_table_entry"><para role=
"func_signature">
29251 <primary>pg_create_physical_replication_slot
</primary>
29253 <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> )
29254 <returnvalue>record
</returnvalue>
29255 (
<parameter>slot_name
</parameter> <type>name
</type>,
29256 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29259 Creates a new physical replication slot named
29260 <parameter>slot_name
</parameter>. The optional second parameter,
29261 when
<literal>true
</literal>, specifies that the
<acronym>LSN
</acronym> for this
29262 replication slot be reserved immediately; otherwise
29263 the
<acronym>LSN
</acronym> is reserved on first connection from a streaming
29264 replication client. Streaming changes from a physical slot is only
29265 possible with the streaming-replication protocol
—
29266 see
<xref linkend=
"protocol-replication"/>. The optional third
29267 parameter,
<parameter>temporary
</parameter>, when set to true, specifies that
29268 the slot should not be permanently stored to disk and is only meant
29269 for use by the current session. Temporary slots are also
29270 released upon any error. This function corresponds
29271 to the replication protocol command
<literal>CREATE_REPLICATION_SLOT
29272 ... PHYSICAL
</literal>.
29277 <entry role=
"func_table_entry"><para role=
"func_signature">
29279 <primary>pg_drop_replication_slot
</primary>
29281 <function>pg_drop_replication_slot
</function> (
<parameter>slot_name
</parameter> <type>name
</type> )
29282 <returnvalue>void
</returnvalue>
29285 Drops the physical or logical replication slot
29286 named
<parameter>slot_name
</parameter>. Same as replication protocol
29287 command
<literal>DROP_REPLICATION_SLOT
</literal>. For logical slots, this must
29288 be called while connected to the same database the slot was created on.
29293 <entry id=
"pg-create-logical-replication-slot" role=
"func_table_entry"><para role=
"func_signature">
29295 <primary>pg_create_logical_replication_slot
</primary>
29297 <function>pg_create_logical_replication_slot
</function> (
<parameter>slot_name
</parameter> <type>name
</type>,
<parameter>plugin
</parameter> <type>name
</type> <optional>,
<parameter>temporary
</parameter> <type>boolean
</type>,
<parameter>twophase
</parameter> <type>boolean
</type>,
<parameter>failover
</parameter> <type>boolean
</type> </optional> )
29298 <returnvalue>record
</returnvalue>
29299 (
<parameter>slot_name
</parameter> <type>name
</type>,
29300 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29303 Creates a new logical (decoding) replication slot named
29304 <parameter>slot_name
</parameter> using the output plugin
29305 <parameter>plugin
</parameter>. The optional third
29306 parameter,
<parameter>temporary
</parameter>, when set to true, specifies that
29307 the slot should not be permanently stored to disk and is only meant
29308 for use by the current session. Temporary slots are also
29309 released upon any error. The optional fourth parameter,
29310 <parameter>twophase
</parameter>, when set to true, specifies
29311 that the decoding of prepared transactions is enabled for this
29312 slot. The optional fifth parameter,
29313 <parameter>failover
</parameter>, when set to true,
29314 specifies that this slot is enabled to be synced to the
29315 standbys so that logical replication can be resumed after
29316 failover. A call to this function has the same effect as
29317 the replication protocol command
29318 <literal>CREATE_REPLICATION_SLOT ... LOGICAL
</literal>.
29323 <entry role=
"func_table_entry"><para role=
"func_signature">
29325 <primary>pg_copy_physical_replication_slot
</primary>
29327 <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> )
29328 <returnvalue>record
</returnvalue>
29329 (
<parameter>slot_name
</parameter> <type>name
</type>,
29330 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29333 Copies an existing physical replication slot named
<parameter>src_slot_name
</parameter>
29334 to a physical replication slot named
<parameter>dst_slot_name
</parameter>.
29335 The copied physical slot starts to reserve WAL from the same
<acronym>LSN
</acronym> as the
29337 <parameter>temporary
</parameter> is optional. If
<parameter>temporary
</parameter>
29338 is omitted, the same value as the source slot is used.
29343 <entry role=
"func_table_entry"><para role=
"func_signature">
29345 <primary>pg_copy_logical_replication_slot
</primary>
29347 <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> )
29348 <returnvalue>record
</returnvalue>
29349 (
<parameter>slot_name
</parameter> <type>name
</type>,
29350 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29353 Copies an existing logical replication slot
29354 named
<parameter>src_slot_name
</parameter> to a logical replication
29355 slot named
<parameter>dst_slot_name
</parameter>, optionally changing
29356 the output plugin and persistence. The copied logical slot starts
29357 from the same
<acronym>LSN
</acronym> as the source logical slot. Both
29358 <parameter>temporary
</parameter> and
<parameter>plugin
</parameter> are
29359 optional; if they are omitted, the values of the source slot are used.
29364 <entry id=
"pg-logical-slot-get-changes" role=
"func_table_entry"><para role=
"func_signature">
29366 <primary>pg_logical_slot_get_changes
</primary>
29368 <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> )
29369 <returnvalue>setof record
</returnvalue>
29370 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29371 <parameter>xid
</parameter> <type>xid
</type>,
29372 <parameter>data
</parameter> <type>text
</type> )
29375 Returns changes in the slot
<parameter>slot_name
</parameter>, starting
29376 from the point from which changes have been consumed last. If
29377 <parameter>upto_lsn
</parameter>
29378 and
<parameter>upto_nchanges
</parameter> are NULL,
29379 logical decoding will continue until end of WAL. If
29380 <parameter>upto_lsn
</parameter> is non-NULL, decoding will include only
29381 those transactions which commit prior to the specified LSN. If
29382 <parameter>upto_nchanges
</parameter> is non-NULL, decoding will
29383 stop when the number of rows produced by decoding exceeds
29384 the specified value. Note, however, that the actual number of
29385 rows returned may be larger, since this limit is only checked after
29386 adding the rows produced when decoding each new transaction commit.
29387 If the specified slot is a logical failover slot then the function will
29388 not return until all physical slots specified in
29389 <link linkend=
"guc-synchronized-standby-slots"><varname>synchronized_standby_slots
</varname></link>
29390 have confirmed WAL receipt.
29395 <entry id=
"pg-logical-slot-peek-changes" role=
"func_table_entry"><para role=
"func_signature">
29397 <primary>pg_logical_slot_peek_changes
</primary>
29399 <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> )
29400 <returnvalue>setof record
</returnvalue>
29401 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29402 <parameter>xid
</parameter> <type>xid
</type>,
29403 <parameter>data
</parameter> <type>text
</type> )
29407 the
<function>pg_logical_slot_get_changes()
</function> function,
29408 except that changes are not consumed; that is, they will be returned
29409 again on future calls.
29414 <entry role=
"func_table_entry"><para role=
"func_signature">
29416 <primary>pg_logical_slot_get_binary_changes
</primary>
29418 <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> )
29419 <returnvalue>setof record
</returnvalue>
29420 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29421 <parameter>xid
</parameter> <type>xid
</type>,
29422 <parameter>data
</parameter> <type>bytea
</type> )
29426 the
<function>pg_logical_slot_get_changes()
</function> function,
29427 except that changes are returned as
<type>bytea
</type>.
29432 <entry role=
"func_table_entry"><para role=
"func_signature">
29434 <primary>pg_logical_slot_peek_binary_changes
</primary>
29436 <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> )
29437 <returnvalue>setof record
</returnvalue>
29438 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29439 <parameter>xid
</parameter> <type>xid
</type>,
29440 <parameter>data
</parameter> <type>bytea
</type> )
29444 the
<function>pg_logical_slot_peek_changes()
</function> function,
29445 except that changes are returned as
<type>bytea
</type>.
29450 <entry id=
"pg-replication-slot-advance" role=
"func_table_entry"><para role=
"func_signature">
29452 <primary>pg_replication_slot_advance
</primary>
29454 <function>pg_replication_slot_advance
</function> (
<parameter>slot_name
</parameter> <type>name
</type>,
<parameter>upto_lsn
</parameter> <type>pg_lsn
</type> )
29455 <returnvalue>record
</returnvalue>
29456 (
<parameter>slot_name
</parameter> <type>name
</type>,
29457 <parameter>end_lsn
</parameter> <type>pg_lsn
</type> )
29460 Advances the current confirmed position of a replication slot named
29461 <parameter>slot_name
</parameter>. The slot will not be moved backwards,
29462 and it will not be moved beyond the current insert location. Returns
29463 the name of the slot and the actual position that it was advanced to.
29464 The updated slot position information is written out at the next
29465 checkpoint if any advancing is done. So in the event of a crash, the
29466 slot may return to an earlier position. If the specified slot is a
29467 logical failover slot then the function will not return until all
29468 physical slots specified in
29469 <link linkend=
"guc-synchronized-standby-slots"><varname>synchronized_standby_slots
</varname></link>
29470 have confirmed WAL receipt.
29475 <entry id=
"pg-replication-origin-create" role=
"func_table_entry"><para role=
"func_signature">
29477 <primary>pg_replication_origin_create
</primary>
29479 <function>pg_replication_origin_create
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29480 <returnvalue>oid
</returnvalue>
29483 Creates a replication origin with the given external
29484 name, and returns the internal ID assigned to it.
29489 <entry id=
"pg-replication-origin-drop" role=
"func_table_entry"><para role=
"func_signature">
29491 <primary>pg_replication_origin_drop
</primary>
29493 <function>pg_replication_origin_drop
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29494 <returnvalue>void
</returnvalue>
29497 Deletes a previously-created replication origin, including any
29498 associated replay progress.
29503 <entry role=
"func_table_entry"><para role=
"func_signature">
29505 <primary>pg_replication_origin_oid
</primary>
29507 <function>pg_replication_origin_oid
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29508 <returnvalue>oid
</returnvalue>
29511 Looks up a replication origin by name and returns the internal ID. If
29512 no such replication origin is found,
<literal>NULL
</literal> is
29518 <entry id=
"pg-replication-origin-session-setup" role=
"func_table_entry"><para role=
"func_signature">
29520 <primary>pg_replication_origin_session_setup
</primary>
29522 <function>pg_replication_origin_session_setup
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29523 <returnvalue>void
</returnvalue>
29526 Marks the current session as replaying from the given
29527 origin, allowing replay progress to be tracked.
29528 Can only be used if no origin is currently selected.
29529 Use
<function>pg_replication_origin_session_reset
</function> to undo.
29534 <entry role=
"func_table_entry"><para role=
"func_signature">
29536 <primary>pg_replication_origin_session_reset
</primary>
29538 <function>pg_replication_origin_session_reset
</function> ()
29539 <returnvalue>void
</returnvalue>
29542 Cancels the effects
29543 of
<function>pg_replication_origin_session_setup()
</function>.
29548 <entry role=
"func_table_entry"><para role=
"func_signature">
29550 <primary>pg_replication_origin_session_is_setup
</primary>
29552 <function>pg_replication_origin_session_is_setup
</function> ()
29553 <returnvalue>boolean
</returnvalue>
29556 Returns true if a replication origin has been selected in the
29562 <entry id=
"pg-replication-origin-session-progress" role=
"func_table_entry"><para role=
"func_signature">
29564 <primary>pg_replication_origin_session_progress
</primary>
29566 <function>pg_replication_origin_session_progress
</function> (
<parameter>flush
</parameter> <type>boolean
</type> )
29567 <returnvalue>pg_lsn
</returnvalue>
29570 Returns the replay location for the replication origin selected in
29571 the current session. The parameter
<parameter>flush
</parameter>
29572 determines whether the corresponding local transaction will be
29573 guaranteed to have been flushed to disk or not.
29578 <entry id=
"pg-replication-origin-xact-setup" role=
"func_table_entry"><para role=
"func_signature">
29580 <primary>pg_replication_origin_xact_setup
</primary>
29582 <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> )
29583 <returnvalue>void
</returnvalue>
29586 Marks the current transaction as replaying a transaction that has
29587 committed at the given
<acronym>LSN
</acronym> and timestamp. Can
29588 only be called when a replication origin has been selected
29589 using
<function>pg_replication_origin_session_setup
</function>.
29594 <entry id=
"pg-replication-origin-xact-reset" role=
"func_table_entry"><para role=
"func_signature">
29596 <primary>pg_replication_origin_xact_reset
</primary>
29598 <function>pg_replication_origin_xact_reset
</function> ()
29599 <returnvalue>void
</returnvalue>
29602 Cancels the effects of
29603 <function>pg_replication_origin_xact_setup()
</function>.
29608 <entry id=
"pg-replication-origin-advance" role=
"func_table_entry"><para role=
"func_signature">
29610 <primary>pg_replication_origin_advance
</primary>
29612 <function>pg_replication_origin_advance
</function> (
<parameter>node_name
</parameter> <type>text
</type>,
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
29613 <returnvalue>void
</returnvalue>
29616 Sets replication progress for the given node to the given
29617 location. This is primarily useful for setting up the initial
29618 location, or setting a new location after configuration changes and
29619 similar. Be aware that careless use of this function can lead to
29620 inconsistently replicated data.
29625 <entry id=
"pg-replication-origin-progress" role=
"func_table_entry"><para role=
"func_signature">
29627 <primary>pg_replication_origin_progress
</primary>
29629 <function>pg_replication_origin_progress
</function> (
<parameter>node_name
</parameter> <type>text
</type>,
<parameter>flush
</parameter> <type>boolean
</type> )
29630 <returnvalue>pg_lsn
</returnvalue>
29633 Returns the replay location for the given replication origin. The
29634 parameter
<parameter>flush
</parameter> determines whether the
29635 corresponding local transaction will be guaranteed to have been
29636 flushed to disk or not.
29641 <entry id=
"pg-logical-emit-message" role=
"func_table_entry"><para role=
"func_signature">
29643 <primary>pg_logical_emit_message
</primary>
29645 <function>pg_logical_emit_message
</function> (
<parameter>transactional
</parameter> <type>boolean
</type>,
<parameter>prefix
</parameter> <type>text
</type>,
<parameter>content
</parameter> <type>text
</type> [,
<parameter>flush
</parameter> <type>boolean
</type> <literal>DEFAULT
</literal> <literal>false
</literal>] )
29646 <returnvalue>pg_lsn
</returnvalue>
29648 <para role=
"func_signature">
29649 <function>pg_logical_emit_message
</function> (
<parameter>transactional
</parameter> <type>boolean
</type>,
<parameter>prefix
</parameter> <type>text
</type>,
<parameter>content
</parameter> <type>bytea
</type> [,
<parameter>flush
</parameter> <type>boolean
</type> <literal>DEFAULT
</literal> <literal>false
</literal>] )
29650 <returnvalue>pg_lsn
</returnvalue>
29653 Emits a logical decoding message. This can be used to pass generic
29654 messages to logical decoding plugins through
29655 WAL. The
<parameter>transactional
</parameter> parameter specifies if
29656 the message should be part of the current transaction, or if it should
29657 be written immediately and decoded as soon as the logical decoder
29658 reads the record. The
<parameter>prefix
</parameter> parameter is a
29659 textual prefix that can be used by logical decoding plugins to easily
29660 recognize messages that are interesting for them.
29661 The
<parameter>content
</parameter> parameter is the content of the
29662 message, given either in text or binary form.
29663 The
<parameter>flush
</parameter> parameter (default set to
29664 <literal>false
</literal>) controls if the message is immediately
29665 flushed to WAL or not.
<parameter>flush
</parameter> has no effect
29666 with
<parameter>transactional
</parameter>, as the message's WAL
29667 record is flushed along with its transaction.
29672 <entry id=
"pg-sync-replication-slots" role=
"func_table_entry"><para role=
"func_signature">
29674 <primary>pg_sync_replication_slots
</primary>
29676 <function>pg_sync_replication_slots
</function> ()
29677 <returnvalue>void
</returnvalue>
29680 Synchronize the logical failover replication slots from the primary
29681 server to the standby server. This function can only be executed on the
29682 standby server. Temporary synced slots, if any, cannot be used for
29683 logical decoding and must be dropped after promotion. See
29684 <xref linkend=
"logicaldecoding-replication-slots-synchronization"/> for details.
29685 Note that this function cannot be executed if
29686 <link linkend=
"guc-sync-replication-slots"><varname>
29687 sync_replication_slots
</varname></link> is enabled and the slotsync
29688 worker is already running to perform the synchronization of slots.
29693 If, after executing the function,
29694 <link linkend=
"guc-hot-standby-feedback">
29695 <varname>hot_standby_feedback
</varname></link> is disabled on
29696 the standby or the physical slot configured in
29697 <link linkend=
"guc-primary-slot-name">
29698 <varname>primary_slot_name
</varname></link> is
29699 removed, then it is possible that the necessary rows of the
29700 synchronized slot will be removed by the VACUUM process on the primary
29701 server, resulting in the synchronized slot becoming invalidated.
29713 <sect2 id=
"functions-admin-dbobject">
29714 <title>Database Object Management Functions
</title>
29717 The functions shown in
<xref linkend=
"functions-admin-dbsize"/> calculate
29718 the disk space usage of database objects, or assist in presentation
29719 or understanding of usage results.
<literal>bigint
</literal> results
29720 are measured in bytes. If an OID that does
29721 not represent an existing object is passed to one of these
29722 functions,
<literal>NULL
</literal> is returned.
29725 <table id=
"functions-admin-dbsize">
29726 <title>Database Object Size Functions
</title>
29730 <entry role=
"func_table_entry"><para role=
"func_signature">
29741 <entry role=
"func_table_entry"><para role=
"func_signature">
29743 <primary>pg_column_size
</primary>
29745 <function>pg_column_size
</function> (
<type>"any"</type> )
29746 <returnvalue>integer
</returnvalue>
29749 Shows the number of bytes used to store any individual data value. If
29750 applied directly to a table column value, this reflects any
29751 compression that was done.
29756 <entry role=
"func_table_entry"><para role=
"func_signature">
29758 <primary>pg_column_compression
</primary>
29760 <function>pg_column_compression
</function> (
<type>"any"</type> )
29761 <returnvalue>text
</returnvalue>
29764 Shows the compression algorithm that was used to compress
29765 an individual variable-length value. Returns
<literal>NULL
</literal>
29766 if the value is not compressed.
29771 <entry role=
"func_table_entry"><para role=
"func_signature">
29773 <primary>pg_column_toast_chunk_id
</primary>
29775 <function>pg_column_toast_chunk_id
</function> (
<type>"any"</type> )
29776 <returnvalue>oid
</returnvalue>
29779 Shows the
<structfield>chunk_id
</structfield> of an on-disk
29780 <acronym>TOAST
</acronym>ed value. Returns
<literal>NULL
</literal>
29781 if the value is un-
<acronym>TOAST
</acronym>ed or not on-disk. See
29782 <xref linkend=
"storage-toast"/> for more information about
29783 <acronym>TOAST
</acronym>.
29788 <entry role=
"func_table_entry"><para role=
"func_signature">
29790 <primary>pg_database_size
</primary>
29792 <function>pg_database_size
</function> (
<type>name
</type> )
29793 <returnvalue>bigint
</returnvalue>
29795 <para role=
"func_signature">
29796 <function>pg_database_size
</function> (
<type>oid
</type> )
29797 <returnvalue>bigint
</returnvalue>
29800 Computes the total disk space used by the database with the specified
29801 name or OID. To use this function, you must
29802 have
<literal>CONNECT
</literal> privilege on the specified database
29803 (which is granted by default) or have privileges of
29804 the
<literal>pg_read_all_stats
</literal> role.
29809 <entry role=
"func_table_entry"><para role=
"func_signature">
29811 <primary>pg_indexes_size
</primary>
29813 <function>pg_indexes_size
</function> (
<type>regclass
</type> )
29814 <returnvalue>bigint
</returnvalue>
29817 Computes the total disk space used by indexes attached to the
29823 <entry role=
"func_table_entry"><para role=
"func_signature">
29825 <primary>pg_relation_size
</primary>
29827 <function>pg_relation_size
</function> (
<parameter>relation
</parameter> <type>regclass
</type> <optional>,
<parameter>fork
</parameter> <type>text
</type> </optional> )
29828 <returnvalue>bigint
</returnvalue>
29831 Computes the disk space used by one
<quote>fork
</quote> of the
29832 specified relation. (Note that for most purposes it is more
29833 convenient to use the higher-level
29834 functions
<function>pg_total_relation_size
</function>
29835 or
<function>pg_table_size
</function>, which sum the sizes of all
29836 forks.) With one argument, this returns the size of the main data
29837 fork of the relation. The second argument can be provided to specify
29838 which fork to examine:
29839 <itemizedlist spacing=
"compact">
29842 <literal>main
</literal> returns the size of the main
29843 data fork of the relation.
29848 <literal>fsm
</literal> returns the size of the Free Space Map
29849 (see
<xref linkend=
"storage-fsm"/>) associated with the relation.
29854 <literal>vm
</literal> returns the size of the Visibility Map
29855 (see
<xref linkend=
"storage-vm"/>) associated with the relation.
29860 <literal>init
</literal> returns the size of the initialization
29861 fork, if any, associated with the relation.
29869 <entry role=
"func_table_entry"><para role=
"func_signature">
29871 <primary>pg_size_bytes
</primary>
29873 <function>pg_size_bytes
</function> (
<type>text
</type> )
29874 <returnvalue>bigint
</returnvalue>
29877 Converts a size in human-readable format (as returned
29878 by
<function>pg_size_pretty
</function>) into bytes. Valid units are
29879 <literal>bytes
</literal>,
<literal>B
</literal>,
<literal>kB
</literal>,
29880 <literal>MB
</literal>,
<literal>GB
</literal>,
<literal>TB
</literal>,
29881 and
<literal>PB
</literal>.
29886 <entry role=
"func_table_entry"><para role=
"func_signature">
29888 <primary>pg_size_pretty
</primary>
29890 <function>pg_size_pretty
</function> (
<type>bigint
</type> )
29891 <returnvalue>text
</returnvalue>
29893 <para role=
"func_signature">
29894 <function>pg_size_pretty
</function> (
<type>numeric
</type> )
29895 <returnvalue>text
</returnvalue>
29898 Converts a size in bytes into a more easily human-readable format with
29899 size units (bytes, kB, MB, GB, TB, or PB as appropriate). Note that the
29900 units are powers of
2 rather than powers of
10, so
1kB is
1024 bytes,
29901 1MB is
1024<superscript>2</superscript> =
1048576 bytes, and so on.
29906 <entry role=
"func_table_entry"><para role=
"func_signature">
29908 <primary>pg_table_size
</primary>
29910 <function>pg_table_size
</function> (
<type>regclass
</type> )
29911 <returnvalue>bigint
</returnvalue>
29914 Computes the disk space used by the specified table, excluding indexes
29915 (but including its TOAST table if any, free space map, and visibility
29921 <entry role=
"func_table_entry"><para role=
"func_signature">
29923 <primary>pg_tablespace_size
</primary>
29925 <function>pg_tablespace_size
</function> (
<type>name
</type> )
29926 <returnvalue>bigint
</returnvalue>
29928 <para role=
"func_signature">
29929 <function>pg_tablespace_size
</function> (
<type>oid
</type> )
29930 <returnvalue>bigint
</returnvalue>
29933 Computes the total disk space used in the tablespace with the
29934 specified name or OID. To use this function, you must
29935 have
<literal>CREATE
</literal> privilege on the specified tablespace
29936 or have privileges of the
<literal>pg_read_all_stats
</literal> role,
29937 unless it is the default tablespace for the current database.
29942 <entry role=
"func_table_entry"><para role=
"func_signature">
29944 <primary>pg_total_relation_size
</primary>
29946 <function>pg_total_relation_size
</function> (
<type>regclass
</type> )
29947 <returnvalue>bigint
</returnvalue>
29950 Computes the total disk space used by the specified table, including
29951 all indexes and
<acronym>TOAST
</acronym> data. The result is
29952 equivalent to
<function>pg_table_size
</function>
29953 <literal>+
</literal> <function>pg_indexes_size
</function>.
29961 The functions above that operate on tables or indexes accept a
29962 <type>regclass
</type> argument, which is simply the OID of the table or index
29963 in the
<structname>pg_class
</structname> system catalog. You do not have to look up
29964 the OID by hand, however, since the
<type>regclass
</type> data type's input
29965 converter will do the work for you. See
<xref linkend=
"datatype-oid"/>
29970 The functions shown in
<xref linkend=
"functions-admin-dblocation"/> assist
29971 in identifying the specific disk files associated with database objects.
29974 <table id=
"functions-admin-dblocation">
29975 <title>Database Object Location Functions
</title>
29979 <entry role=
"func_table_entry"><para role=
"func_signature">
29990 <entry role=
"func_table_entry"><para role=
"func_signature">
29992 <primary>pg_relation_filenode
</primary>
29994 <function>pg_relation_filenode
</function> (
<parameter>relation
</parameter> <type>regclass
</type> )
29995 <returnvalue>oid
</returnvalue>
29998 Returns the
<quote>filenode
</quote> number currently assigned to the
29999 specified relation. The filenode is the base component of the file
30000 name(s) used for the relation (see
30001 <xref linkend=
"storage-file-layout"/> for more information).
30002 For most relations the result is the same as
30003 <structname>pg_class
</structname>.
<structfield>relfilenode
</structfield>,
30004 but for certain system catalogs
<structfield>relfilenode
</structfield>
30005 is zero and this function must be used to get the correct value. The
30006 function returns NULL if passed a relation that does not have storage,
30012 <entry role=
"func_table_entry"><para role=
"func_signature">
30014 <primary>pg_relation_filepath
</primary>
30016 <function>pg_relation_filepath
</function> (
<parameter>relation
</parameter> <type>regclass
</type> )
30017 <returnvalue>text
</returnvalue>
30020 Returns the entire file path name (relative to the database cluster's
30021 data directory,
<varname>PGDATA
</varname>) of the relation.
30026 <entry role=
"func_table_entry"><para role=
"func_signature">
30028 <primary>pg_filenode_relation
</primary>
30030 <function>pg_filenode_relation
</function> (
<parameter>tablespace
</parameter> <type>oid
</type>,
<parameter>filenode
</parameter> <type>oid
</type> )
30031 <returnvalue>regclass
</returnvalue>
30034 Returns a relation's OID given the tablespace OID and filenode it is
30035 stored under. This is essentially the inverse mapping of
30036 <function>pg_relation_filepath
</function>. For a relation in the
30037 database's default tablespace, the tablespace can be specified as zero.
30038 Returns
<literal>NULL
</literal> if no relation in the current database
30039 is associated with the given values.
30047 <xref linkend=
"functions-admin-collation"/> lists functions used to manage
30051 <table id=
"functions-admin-collation">
30052 <title>Collation Management Functions
</title>
30056 <entry role=
"func_table_entry"><para role=
"func_signature">
30067 <entry role=
"func_table_entry"><para role=
"func_signature">
30069 <primary>pg_collation_actual_version
</primary>
30071 <function>pg_collation_actual_version
</function> (
<type>oid
</type> )
30072 <returnvalue>text
</returnvalue>
30075 Returns the actual version of the collation object as it is currently
30076 installed in the operating system. If this is different from the
30078 <structname>pg_collation
</structname>.
<structfield>collversion
</structfield>,
30079 then objects depending on the collation might need to be rebuilt. See
30080 also
<xref linkend=
"sql-altercollation"/>.
30085 <entry role=
"func_table_entry"><para role=
"func_signature">
30087 <primary>pg_database_collation_actual_version
</primary>
30089 <function>pg_database_collation_actual_version
</function> (
<type>oid
</type> )
30090 <returnvalue>text
</returnvalue>
30093 Returns the actual version of the database's collation as it is currently
30094 installed in the operating system. If this is different from the
30096 <structname>pg_database
</structname>.
<structfield>datcollversion
</structfield>,
30097 then objects depending on the collation might need to be rebuilt. See
30098 also
<xref linkend=
"sql-alterdatabase"/>.
30103 <entry role=
"func_table_entry"><para role=
"func_signature">
30105 <primary>pg_import_system_collations
</primary>
30107 <function>pg_import_system_collations
</function> (
<parameter>schema
</parameter> <type>regnamespace
</type> )
30108 <returnvalue>integer
</returnvalue>
30111 Adds collations to the system
30112 catalog
<structname>pg_collation
</structname> based on all the locales
30113 it finds in the operating system. This is
30114 what
<command>initdb
</command> uses; see
30115 <xref linkend=
"collation-managing"/> for more details. If additional
30116 locales are installed into the operating system later on, this
30117 function can be run again to add collations for the new locales.
30118 Locales that match existing entries
30119 in
<structname>pg_collation
</structname> will be skipped. (But
30120 collation objects based on locales that are no longer present in the
30121 operating system are not removed by this function.)
30122 The
<parameter>schema
</parameter> parameter would typically
30123 be
<literal>pg_catalog
</literal>, but that is not a requirement; the
30124 collations could be installed into some other schema as well. The
30125 function returns the number of new collation objects it created.
30126 Use of this function is restricted to superusers.
30134 <xref linkend=
"functions-info-partition"/> lists functions that provide
30135 information about the structure of partitioned tables.
30138 <table id=
"functions-info-partition">
30139 <title>Partitioning Information Functions
</title>
30143 <entry role=
"func_table_entry"><para role=
"func_signature">
30154 <entry role=
"func_table_entry"><para role=
"func_signature">
30156 <primary>pg_partition_tree
</primary>
30158 <function>pg_partition_tree
</function> (
<type>regclass
</type> )
30159 <returnvalue>setof record
</returnvalue>
30160 (
<parameter>relid
</parameter> <type>regclass
</type>,
30161 <parameter>parentrelid
</parameter> <type>regclass
</type>,
30162 <parameter>isleaf
</parameter> <type>boolean
</type>,
30163 <parameter>level
</parameter> <type>integer
</type> )
30166 Lists the tables or indexes in the partition tree of the
30167 given partitioned table or partitioned index, with one row for each
30168 partition. Information provided includes the OID of the partition,
30169 the OID of its immediate parent, a boolean value telling if the
30170 partition is a leaf, and an integer telling its level in the hierarchy.
30171 The level value is
0 for the input table or index,
1 for its
30172 immediate child partitions,
2 for their partitions, and so on.
30173 Returns no rows if the relation does not exist or is not a partition
30174 or partitioned table.
30179 <entry role=
"func_table_entry"><para role=
"func_signature">
30181 <primary>pg_partition_ancestors
</primary>
30183 <function>pg_partition_ancestors
</function> (
<type>regclass
</type> )
30184 <returnvalue>setof regclass
</returnvalue>
30187 Lists the ancestor relations of the given partition,
30188 including the relation itself. Returns no rows if the relation
30189 does not exist or is not a partition or partitioned table.
30194 <entry role=
"func_table_entry"><para role=
"func_signature">
30196 <primary>pg_partition_root
</primary>
30198 <function>pg_partition_root
</function> (
<type>regclass
</type> )
30199 <returnvalue>regclass
</returnvalue>
30202 Returns the top-most parent of the partition tree to which the given
30203 relation belongs. Returns
<literal>NULL
</literal> if the relation
30204 does not exist or is not a partition or partitioned table.
30212 For example, to check the total size of the data contained in a
30213 partitioned table
<structname>measurement
</structname>, one could use the
30216 SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
30217 FROM pg_partition_tree('measurement');
30223 <sect2 id=
"functions-admin-index">
30224 <title>Index Maintenance Functions
</title>
30227 <xref linkend=
"functions-admin-index-table"/> shows the functions
30228 available for index maintenance tasks. (Note that these maintenance
30229 tasks are normally done automatically by autovacuum; use of these
30230 functions is only required in special cases.)
30231 These functions cannot be executed during recovery.
30232 Use of these functions is restricted to superusers and the owner
30233 of the given index.
30236 <table id=
"functions-admin-index-table">
30237 <title>Index Maintenance Functions
</title>
30241 <entry role=
"func_table_entry"><para role=
"func_signature">
30252 <entry role=
"func_table_entry"><para role=
"func_signature">
30254 <primary>brin_summarize_new_values
</primary>
30256 <function>brin_summarize_new_values
</function> (
<parameter>index
</parameter> <type>regclass
</type> )
30257 <returnvalue>integer
</returnvalue>
30260 Scans the specified BRIN index to find page ranges in the base table
30261 that are not currently summarized by the index; for any such range it
30262 creates a new summary index tuple by scanning those table pages.
30263 Returns the number of new page range summaries that were inserted
30269 <entry role=
"func_table_entry"><para role=
"func_signature">
30271 <primary>brin_summarize_range
</primary>
30273 <function>brin_summarize_range
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>blockNumber
</parameter> <type>bigint
</type> )
30274 <returnvalue>integer
</returnvalue>
30277 Summarizes the page range covering the given block, if not already
30278 summarized. This is
30279 like
<function>brin_summarize_new_values
</function> except that it
30280 only processes the page range that covers the given table block number.
30285 <entry role=
"func_table_entry"><para role=
"func_signature">
30287 <primary>brin_desummarize_range
</primary>
30289 <function>brin_desummarize_range
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>blockNumber
</parameter> <type>bigint
</type> )
30290 <returnvalue>void
</returnvalue>
30293 Removes the BRIN index tuple that summarizes the page range covering
30294 the given table block, if there is one.
30299 <entry role=
"func_table_entry"><para role=
"func_signature">
30301 <primary>gin_clean_pending_list
</primary>
30303 <function>gin_clean_pending_list
</function> (
<parameter>index
</parameter> <type>regclass
</type> )
30304 <returnvalue>bigint
</returnvalue>
30307 Cleans up the
<quote>pending
</quote> list of the specified GIN index
30308 by moving entries in it, in bulk, to the main GIN data structure.
30309 Returns the number of pages removed from the pending list.
30310 If the argument is a GIN index built with
30311 the
<literal>fastupdate
</literal> option disabled, no cleanup happens
30312 and the result is zero, because the index doesn't have a pending list.
30313 See
<xref linkend=
"gin-fast-update"/> and
<xref linkend=
"gin-tips"/>
30314 for details about the pending list and
<literal>fastupdate
</literal>
30324 <sect2 id=
"functions-admin-genfile">
30325 <title>Generic File Access Functions
</title>
30328 The functions shown in
<xref
30329 linkend=
"functions-admin-genfile-table"/> provide native access to
30330 files on the machine hosting the server. Only files within the
30331 database cluster directory and the
<varname>log_directory
</varname> can be
30332 accessed, unless the user is a superuser or is granted the role
30333 <literal>pg_read_server_files
</literal>. Use a relative path for files in
30334 the cluster directory, and a path matching the
<varname>log_directory
</varname>
30335 configuration setting for log files.
30339 Note that granting users the EXECUTE privilege on
30340 <function>pg_read_file()
</function>, or related functions, allows them the
30341 ability to read any file on the server that the database server process can
30342 read; these functions bypass all in-database privilege checks. This means
30343 that, for example, a user with such access is able to read the contents of
30344 the
<structname>pg_authid
</structname> table where authentication
30345 information is stored, as well as read any table data in the database.
30346 Therefore, granting access to these functions should be carefully
30351 When granting privilege on these functions, note that the table entries
30352 showing optional parameters are mostly implemented as several physical
30353 functions with different parameter lists. Privilege must be granted
30354 separately on each such function, if it is to be
30355 used.
<application>psql
</application>'s
<command>\df
</command> command
30356 can be useful to check what the actual function signatures are.
30360 Some of these functions take an optional
<parameter>missing_ok
</parameter>
30361 parameter, which specifies the behavior when the file or directory does
30362 not exist. If
<literal>true
</literal>, the function
30363 returns
<literal>NULL
</literal> or an empty result set, as appropriate.
30364 If
<literal>false
</literal>, an error is raised. (Failure conditions
30365 other than
<quote>file not found
</quote> are reported as errors in any
30366 case.) The default is
<literal>false
</literal>.
30369 <table id=
"functions-admin-genfile-table">
30370 <title>Generic File Access Functions
</title>
30374 <entry role=
"func_table_entry"><para role=
"func_signature">
30385 <entry role=
"func_table_entry"><para role=
"func_signature">
30387 <primary>pg_ls_dir
</primary>
30389 <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> )
30390 <returnvalue>setof text
</returnvalue>
30393 Returns the names of all files (and directories and other special
30394 files) in the specified
30395 directory. The
<parameter>include_dot_dirs
</parameter> parameter
30396 indicates whether
<quote>.
</quote> and
<quote>..
</quote> are to be
30397 included in the result set; the default is to exclude them. Including
30398 them can be useful when
<parameter>missing_ok
</parameter>
30399 is
<literal>true
</literal>, to distinguish an empty directory from a
30400 non-existent directory.
30403 This function is restricted to superusers by default, but other users
30404 can be granted EXECUTE to run the function.
30409 <entry role=
"func_table_entry"><para role=
"func_signature">
30411 <primary>pg_ls_logdir
</primary>
30413 <function>pg_ls_logdir
</function> ()
30414 <returnvalue>setof record
</returnvalue>
30415 (
<parameter>name
</parameter> <type>text
</type>,
30416 <parameter>size
</parameter> <type>bigint
</type>,
30417 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30420 Returns the name, size, and last modification time (mtime) of each
30421 ordinary file in the server's log directory. Filenames beginning with
30422 a dot, directories, and other special files are excluded.
30425 This function is restricted to superusers and roles with privileges of
30426 the
<literal>pg_monitor
</literal> role by default, but other users can
30427 be granted EXECUTE to run the function.
30432 <entry role=
"func_table_entry"><para role=
"func_signature">
30434 <primary>pg_ls_waldir
</primary>
30436 <function>pg_ls_waldir
</function> ()
30437 <returnvalue>setof record
</returnvalue>
30438 (
<parameter>name
</parameter> <type>text
</type>,
30439 <parameter>size
</parameter> <type>bigint
</type>,
30440 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30443 Returns the name, size, and last modification time (mtime) of each
30444 ordinary file in the server's write-ahead log (WAL) directory.
30445 Filenames beginning with a dot, directories, and other special files
30449 This function is restricted to superusers and roles with privileges of
30450 the
<literal>pg_monitor
</literal> role by default, but other users can
30451 be granted EXECUTE to run the function.
30456 <entry role=
"func_table_entry"><para role=
"func_signature">
30458 <primary>pg_ls_logicalmapdir
</primary>
30460 <function>pg_ls_logicalmapdir
</function> ()
30461 <returnvalue>setof record
</returnvalue>
30462 (
<parameter>name
</parameter> <type>text
</type>,
30463 <parameter>size
</parameter> <type>bigint
</type>,
30464 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30467 Returns the name, size, and last modification time (mtime) of each
30468 ordinary file in the server's
<filename>pg_logical/mappings
</filename>
30469 directory. Filenames beginning with a dot, directories, and other
30470 special files are excluded.
30473 This function is restricted to superusers and members of
30474 the
<literal>pg_monitor
</literal> role by default, but other users can
30475 be granted EXECUTE to run the function.
30480 <entry role=
"func_table_entry"><para role=
"func_signature">
30482 <primary>pg_ls_logicalsnapdir
</primary>
30484 <function>pg_ls_logicalsnapdir
</function> ()
30485 <returnvalue>setof record
</returnvalue>
30486 (
<parameter>name
</parameter> <type>text
</type>,
30487 <parameter>size
</parameter> <type>bigint
</type>,
30488 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30491 Returns the name, size, and last modification time (mtime) of each
30492 ordinary file in the server's
<filename>pg_logical/snapshots
</filename>
30493 directory. Filenames beginning with a dot, directories, and other
30494 special files are excluded.
30497 This function is restricted to superusers and members of
30498 the
<literal>pg_monitor
</literal> role by default, but other users can
30499 be granted EXECUTE to run the function.
30504 <entry role=
"func_table_entry"><para role=
"func_signature">
30506 <primary>pg_ls_replslotdir
</primary>
30508 <function>pg_ls_replslotdir
</function> (
<parameter>slot_name
</parameter> <type>text
</type> )
30509 <returnvalue>setof record
</returnvalue>
30510 (
<parameter>name
</parameter> <type>text
</type>,
30511 <parameter>size
</parameter> <type>bigint
</type>,
30512 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30515 Returns the name, size, and last modification time (mtime) of each
30516 ordinary file in the server's
<filename>pg_replslot/slot_name
</filename>
30517 directory, where
<parameter>slot_name
</parameter> is the name of the
30518 replication slot provided as input of the function. Filenames beginning
30519 with a dot, directories, and other special files are excluded.
30522 This function is restricted to superusers and members of
30523 the
<literal>pg_monitor
</literal> role by default, but other users can
30524 be granted EXECUTE to run the function.
30529 <entry role=
"func_table_entry"><para role=
"func_signature">
30531 <primary>pg_ls_archive_statusdir
</primary>
30533 <function>pg_ls_archive_statusdir
</function> ()
30534 <returnvalue>setof record
</returnvalue>
30535 (
<parameter>name
</parameter> <type>text
</type>,
30536 <parameter>size
</parameter> <type>bigint
</type>,
30537 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30540 Returns the name, size, and last modification time (mtime) of each
30541 ordinary file in the server's WAL archive status directory
30542 (
<filename>pg_wal/archive_status
</filename>). Filenames beginning
30543 with a dot, directories, and other special files are excluded.
30546 This function is restricted to superusers and members of
30547 the
<literal>pg_monitor
</literal> role by default, but other users can
30548 be granted EXECUTE to run the function.
30553 <entry role=
"func_table_entry"><para role=
"func_signature">
30556 <primary>pg_ls_tmpdir
</primary>
30558 <function>pg_ls_tmpdir
</function> (
<optional> <parameter>tablespace
</parameter> <type>oid
</type> </optional> )
30559 <returnvalue>setof record
</returnvalue>
30560 (
<parameter>name
</parameter> <type>text
</type>,
30561 <parameter>size
</parameter> <type>bigint
</type>,
30562 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30565 Returns the name, size, and last modification time (mtime) of each
30566 ordinary file in the temporary file directory for the
30567 specified
<parameter>tablespace
</parameter>.
30568 If
<parameter>tablespace
</parameter> is not provided,
30569 the
<literal>pg_default
</literal> tablespace is examined. Filenames
30570 beginning with a dot, directories, and other special files are
30574 This function is restricted to superusers and members of
30575 the
<literal>pg_monitor
</literal> role by default, but other users can
30576 be granted EXECUTE to run the function.
30581 <entry role=
"func_table_entry"><para role=
"func_signature">
30583 <primary>pg_read_file
</primary>
30585 <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> )
30586 <returnvalue>text
</returnvalue>
30589 Returns all or part of a text file, starting at the
30590 given byte
<parameter>offset
</parameter>, returning at
30591 most
<parameter>length
</parameter> bytes (less if the end of file is
30592 reached first). If
<parameter>offset
</parameter> is negative, it is
30593 relative to the end of the file. If
<parameter>offset
</parameter>
30594 and
<parameter>length
</parameter> are omitted, the entire file is
30595 returned. The bytes read from the file are interpreted as a string in
30596 the database's encoding; an error is thrown if they are not valid in
30600 This function is restricted to superusers by default, but other users
30601 can be granted EXECUTE to run the function.
30606 <entry role=
"func_table_entry"><para role=
"func_signature">
30608 <primary>pg_read_binary_file
</primary>
30610 <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> )
30611 <returnvalue>bytea
</returnvalue>
30614 Returns all or part of a file. This function is identical to
30615 <function>pg_read_file
</function> except that it can read arbitrary
30616 binary data, returning the result as
<type>bytea
</type>
30617 not
<type>text
</type>; accordingly, no encoding checks are performed.
30620 This function is restricted to superusers by default, but other users
30621 can be granted EXECUTE to run the function.
30624 In combination with the
<function>convert_from
</function> function,
30625 this function can be used to read a text file in a specified encoding
30626 and convert to the database's encoding:
30628 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
30634 <entry role=
"func_table_entry"><para role=
"func_signature">
30636 <primary>pg_stat_file
</primary>
30638 <function>pg_stat_file
</function> (
<parameter>filename
</parameter> <type>text
</type> <optional>,
<parameter>missing_ok
</parameter> <type>boolean
</type> </optional> )
30639 <returnvalue>record
</returnvalue>
30640 (
<parameter>size
</parameter> <type>bigint
</type>,
30641 <parameter>access
</parameter> <type>timestamp with time zone
</type>,
30642 <parameter>modification
</parameter> <type>timestamp with time zone
</type>,
30643 <parameter>change
</parameter> <type>timestamp with time zone
</type>,
30644 <parameter>creation
</parameter> <type>timestamp with time zone
</type>,
30645 <parameter>isdir
</parameter> <type>boolean
</type> )
30648 Returns a record containing the file's size, last access time stamp,
30649 last modification time stamp, last file status change time stamp (Unix
30650 platforms only), file creation time stamp (Windows only), and a flag
30651 indicating if it is a directory.
30654 This function is restricted to superusers by default, but other users
30655 can be granted EXECUTE to run the function.
30665 <sect2 id=
"functions-advisory-locks">
30666 <title>Advisory Lock Functions
</title>
30669 The functions shown in
<xref linkend=
"functions-advisory-locks-table"/>
30670 manage advisory locks. For details about proper use of these functions,
30671 see
<xref linkend=
"advisory-locks"/>.
30675 All these functions are intended to be used to lock application-defined
30676 resources, which can be identified either by a single
64-bit key value or
30677 two
32-bit key values (note that these two key spaces do not overlap).
30678 If another session already holds a conflicting lock on the same resource
30679 identifier, the functions will either wait until the resource becomes
30680 available, or return a
<literal>false
</literal> result, as appropriate for
30682 Locks can be either shared or exclusive: a shared lock does not conflict
30683 with other shared locks on the same resource, only with exclusive locks.
30684 Locks can be taken at session level (so that they are held until released
30685 or the session ends) or at transaction level (so that they are held until
30686 the current transaction ends; there is no provision for manual release).
30687 Multiple session-level lock requests stack, so that if the same resource
30688 identifier is locked three times there must then be three unlock requests
30689 to release the resource in advance of session end.
30692 <table id=
"functions-advisory-locks-table">
30693 <title>Advisory Lock Functions
</title>
30697 <entry role=
"func_table_entry"><para role=
"func_signature">
30708 <entry role=
"func_table_entry"><para role=
"func_signature">
30710 <primary>pg_advisory_lock
</primary>
30712 <function>pg_advisory_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30713 <returnvalue>void
</returnvalue>
30715 <para role=
"func_signature">
30716 <function>pg_advisory_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30717 <returnvalue>void
</returnvalue>
30720 Obtains an exclusive session-level advisory lock, waiting if necessary.
30725 <entry role=
"func_table_entry"><para role=
"func_signature">
30727 <primary>pg_advisory_lock_shared
</primary>
30729 <function>pg_advisory_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30730 <returnvalue>void
</returnvalue>
30732 <para role=
"func_signature">
30733 <function>pg_advisory_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30734 <returnvalue>void
</returnvalue>
30737 Obtains a shared session-level advisory lock, waiting if necessary.
30742 <entry role=
"func_table_entry"><para role=
"func_signature">
30744 <primary>pg_advisory_unlock
</primary>
30746 <function>pg_advisory_unlock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30747 <returnvalue>boolean
</returnvalue>
30749 <para role=
"func_signature">
30750 <function>pg_advisory_unlock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30751 <returnvalue>boolean
</returnvalue>
30754 Releases a previously-acquired exclusive session-level advisory lock.
30755 Returns
<literal>true
</literal> if the lock is successfully released.
30756 If the lock was not held,
<literal>false
</literal> is returned, and in
30757 addition, an SQL warning will be reported by the server.
30762 <entry role=
"func_table_entry"><para role=
"func_signature">
30764 <primary>pg_advisory_unlock_all
</primary>
30766 <function>pg_advisory_unlock_all
</function> ()
30767 <returnvalue>void
</returnvalue>
30770 Releases all session-level advisory locks held by the current session.
30771 (This function is implicitly invoked at session end, even if the
30772 client disconnects ungracefully.)
30777 <entry role=
"func_table_entry"><para role=
"func_signature">
30779 <primary>pg_advisory_unlock_shared
</primary>
30781 <function>pg_advisory_unlock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30782 <returnvalue>boolean
</returnvalue>
30784 <para role=
"func_signature">
30785 <function>pg_advisory_unlock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30786 <returnvalue>boolean
</returnvalue>
30789 Releases a previously-acquired shared session-level advisory lock.
30790 Returns
<literal>true
</literal> if the lock is successfully released.
30791 If the lock was not held,
<literal>false
</literal> is returned, and in
30792 addition, an SQL warning will be reported by the server.
30797 <entry role=
"func_table_entry"><para role=
"func_signature">
30799 <primary>pg_advisory_xact_lock
</primary>
30801 <function>pg_advisory_xact_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30802 <returnvalue>void
</returnvalue>
30804 <para role=
"func_signature">
30805 <function>pg_advisory_xact_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30806 <returnvalue>void
</returnvalue>
30809 Obtains an exclusive transaction-level advisory lock, waiting if
30815 <entry role=
"func_table_entry"><para role=
"func_signature">
30817 <primary>pg_advisory_xact_lock_shared
</primary>
30819 <function>pg_advisory_xact_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30820 <returnvalue>void
</returnvalue>
30822 <para role=
"func_signature">
30823 <function>pg_advisory_xact_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30824 <returnvalue>void
</returnvalue>
30827 Obtains a shared transaction-level advisory lock, waiting if
30833 <entry role=
"func_table_entry"><para role=
"func_signature">
30835 <primary>pg_try_advisory_lock
</primary>
30837 <function>pg_try_advisory_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30838 <returnvalue>boolean
</returnvalue>
30840 <para role=
"func_signature">
30841 <function>pg_try_advisory_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30842 <returnvalue>boolean
</returnvalue>
30845 Obtains an exclusive session-level advisory lock if available.
30846 This will either obtain the lock immediately and
30847 return
<literal>true
</literal>, or return
<literal>false
</literal>
30848 without waiting if the lock cannot be acquired immediately.
30853 <entry role=
"func_table_entry"><para role=
"func_signature">
30855 <primary>pg_try_advisory_lock_shared
</primary>
30857 <function>pg_try_advisory_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30858 <returnvalue>boolean
</returnvalue>
30860 <para role=
"func_signature">
30861 <function>pg_try_advisory_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30862 <returnvalue>boolean
</returnvalue>
30865 Obtains a shared session-level advisory lock if available.
30866 This will either obtain the lock immediately and
30867 return
<literal>true
</literal>, or return
<literal>false
</literal>
30868 without waiting if the lock cannot be acquired immediately.
30873 <entry role=
"func_table_entry"><para role=
"func_signature">
30875 <primary>pg_try_advisory_xact_lock
</primary>
30877 <function>pg_try_advisory_xact_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30878 <returnvalue>boolean
</returnvalue>
30880 <para role=
"func_signature">
30881 <function>pg_try_advisory_xact_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30882 <returnvalue>boolean
</returnvalue>
30885 Obtains an exclusive transaction-level advisory lock if available.
30886 This will either obtain the lock immediately and
30887 return
<literal>true
</literal>, or return
<literal>false
</literal>
30888 without waiting if the lock cannot be acquired immediately.
30893 <entry role=
"func_table_entry"><para role=
"func_signature">
30895 <primary>pg_try_advisory_xact_lock_shared
</primary>
30897 <function>pg_try_advisory_xact_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30898 <returnvalue>boolean
</returnvalue>
30900 <para role=
"func_signature">
30901 <function>pg_try_advisory_xact_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30902 <returnvalue>boolean
</returnvalue>
30905 Obtains a shared transaction-level advisory lock if available.
30906 This will either obtain the lock immediately and
30907 return
<literal>true
</literal>, or return
<literal>false
</literal>
30908 without waiting if the lock cannot be acquired immediately.
30919 <sect1 id=
"functions-trigger">
30920 <title>Trigger Functions
</title>
30923 While many uses of triggers involve user-written trigger functions,
30924 <productname>PostgreSQL
</productname> provides a few built-in trigger
30925 functions that can be used directly in user-defined triggers. These
30926 are summarized in
<xref linkend=
"builtin-triggers-table"/>.
30927 (Additional built-in trigger functions exist, which implement foreign
30928 key constraints and deferred index constraints. Those are not documented
30929 here since users need not use them directly.)
30933 For more information about creating triggers, see
30934 <xref linkend=
"sql-createtrigger"/>.
30937 <table id=
"builtin-triggers-table">
30938 <title>Built-In Trigger Functions
</title>
30942 <entry role=
"func_table_entry"><para role=
"func_signature">
30956 <entry role=
"func_table_entry"><para role=
"func_signature">
30958 <primary>suppress_redundant_updates_trigger
</primary>
30960 <function>suppress_redundant_updates_trigger
</function> ( )
30961 <returnvalue>trigger
</returnvalue>
30964 Suppresses do-nothing update operations. See below for details.
30967 <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()
</literal>
30972 <entry role=
"func_table_entry"><para role=
"func_signature">
30974 <primary>tsvector_update_trigger
</primary>
30976 <function>tsvector_update_trigger
</function> ( )
30977 <returnvalue>trigger
</returnvalue>
30980 Automatically updates a
<type>tsvector
</type> column from associated
30981 plain-text document column(s). The text search configuration to use
30982 is specified by name as a trigger argument. See
30983 <xref linkend=
"textsearch-update-triggers"/> for details.
30986 <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)
</literal>
30991 <entry role=
"func_table_entry"><para role=
"func_signature">
30993 <primary>tsvector_update_trigger_column
</primary>
30995 <function>tsvector_update_trigger_column
</function> ( )
30996 <returnvalue>trigger
</returnvalue>
30999 Automatically updates a
<type>tsvector
</type> column from associated
31000 plain-text document column(s). The text search configuration to use
31001 is taken from a
<type>regconfig
</type> column of the table. See
31002 <xref linkend=
"textsearch-update-triggers"/> for details.
31005 <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)
</literal>
31013 The
<function>suppress_redundant_updates_trigger
</function> function,
31014 when applied as a row-level
<literal>BEFORE UPDATE
</literal> trigger,
31015 will prevent any update that does not actually change the data in the
31016 row from taking place. This overrides the normal behavior which always
31017 performs a physical row update
31018 regardless of whether or not the data has changed. (This normal behavior
31019 makes updates run faster, since no checking is required, and is also
31020 useful in certain cases.)
31024 Ideally, you should avoid running updates that don't actually
31025 change the data in the record. Redundant updates can cost considerable
31026 unnecessary time, especially if there are lots of indexes to alter,
31027 and space in dead rows that will eventually have to be vacuumed.
31028 However, detecting such situations in client code is not
31029 always easy, or even possible, and writing expressions to detect
31030 them can be error-prone. An alternative is to use
31031 <function>suppress_redundant_updates_trigger
</function>, which will skip
31032 updates that don't change the data. You should use this with care,
31033 however. The trigger takes a small but non-trivial time for each record,
31034 so if most of the records affected by updates do actually change,
31035 use of this trigger will make updates run slower on average.
31039 The
<function>suppress_redundant_updates_trigger
</function> function can be
31040 added to a table like this:
31042 CREATE TRIGGER z_min_update
31043 BEFORE UPDATE ON tablename
31044 FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger();
31046 In most cases, you need to fire this trigger last for each row, so that
31047 it does not override other triggers that might wish to alter the row.
31048 Bearing in mind that triggers fire in name order, you would therefore
31049 choose a trigger name that comes after the name of any other trigger
31050 you might have on the table. (Hence the
<quote>z
</quote> prefix in the
31055 <sect1 id=
"functions-event-triggers">
31056 <title>Event Trigger Functions
</title>
31059 <productname>PostgreSQL
</productname> provides these helper functions
31060 to retrieve information from event triggers.
31064 For more information about event triggers,
31065 see
<xref linkend=
"event-triggers"/>.
31068 <sect2 id=
"pg-event-trigger-ddl-command-end-functions">
31069 <title>Capturing Changes at Command End
</title>
31072 <primary>pg_event_trigger_ddl_commands
</primary>
31076 <function>pg_event_trigger_ddl_commands
</function> ()
<returnvalue>setof record
</returnvalue>
31080 <function>pg_event_trigger_ddl_commands
</function> returns a list of
31081 <acronym>DDL
</acronym> commands executed by each user action,
31082 when invoked in a function attached to a
31083 <literal>ddl_command_end
</literal> event trigger. If called in any other
31084 context, an error is raised.
31085 <function>pg_event_trigger_ddl_commands
</function> returns one row for each
31086 base command executed; some commands that are a single SQL sentence
31087 may return more than one row. This function returns the following
31094 <entry>Name
</entry>
31095 <entry>Type
</entry>
31096 <entry>Description
</entry>
31102 <entry><literal>classid
</literal></entry>
31103 <entry><type>oid
</type></entry>
31104 <entry>OID of catalog the object belongs in
</entry>
31107 <entry><literal>objid
</literal></entry>
31108 <entry><type>oid
</type></entry>
31109 <entry>OID of the object itself
</entry>
31112 <entry><literal>objsubid
</literal></entry>
31113 <entry><type>integer
</type></entry>
31114 <entry>Sub-object ID (e.g., attribute number for a column)
</entry>
31117 <entry><literal>command_tag
</literal></entry>
31118 <entry><type>text
</type></entry>
31119 <entry>Command tag
</entry>
31122 <entry><literal>object_type
</literal></entry>
31123 <entry><type>text
</type></entry>
31124 <entry>Type of the object
</entry>
31127 <entry><literal>schema_name
</literal></entry>
31128 <entry><type>text
</type></entry>
31130 Name of the schema the object belongs in, if any; otherwise
<literal>NULL
</literal>.
31131 No quoting is applied.
31135 <entry><literal>object_identity
</literal></entry>
31136 <entry><type>text
</type></entry>
31138 Text rendering of the object identity, schema-qualified. Each
31139 identifier included in the identity is quoted if necessary.
31143 <entry><literal>in_extension
</literal></entry>
31144 <entry><type>boolean
</type></entry>
31145 <entry>True if the command is part of an extension script
</entry>
31148 <entry><literal>command
</literal></entry>
31149 <entry><type>pg_ddl_command
</type></entry>
31151 A complete representation of the command, in internal format.
31152 This cannot be output directly, but it can be passed to other
31153 functions to obtain different pieces of information about the
31163 <sect2 id=
"pg-event-trigger-sql-drop-functions">
31164 <title>Processing Objects Dropped by a DDL Command
</title>
31167 <primary>pg_event_trigger_dropped_objects
</primary>
31171 <function>pg_event_trigger_dropped_objects
</function> ()
<returnvalue>setof record
</returnvalue>
31175 <function>pg_event_trigger_dropped_objects
</function> returns a list of all objects
31176 dropped by the command in whose
<literal>sql_drop
</literal> event it is called.
31177 If called in any other context, an error is raised.
31178 This function returns the following columns:
31184 <entry>Name
</entry>
31185 <entry>Type
</entry>
31186 <entry>Description
</entry>
31192 <entry><literal>classid
</literal></entry>
31193 <entry><type>oid
</type></entry>
31194 <entry>OID of catalog the object belonged in
</entry>
31197 <entry><literal>objid
</literal></entry>
31198 <entry><type>oid
</type></entry>
31199 <entry>OID of the object itself
</entry>
31202 <entry><literal>objsubid
</literal></entry>
31203 <entry><type>integer
</type></entry>
31204 <entry>Sub-object ID (e.g., attribute number for a column)
</entry>
31207 <entry><literal>original
</literal></entry>
31208 <entry><type>boolean
</type></entry>
31209 <entry>True if this was one of the root object(s) of the deletion
</entry>
31212 <entry><literal>normal
</literal></entry>
31213 <entry><type>boolean
</type></entry>
31215 True if there was a normal dependency relationship
31216 in the dependency graph leading to this object
31220 <entry><literal>is_temporary
</literal></entry>
31221 <entry><type>boolean
</type></entry>
31223 True if this was a temporary object
31227 <entry><literal>object_type
</literal></entry>
31228 <entry><type>text
</type></entry>
31229 <entry>Type of the object
</entry>
31232 <entry><literal>schema_name
</literal></entry>
31233 <entry><type>text
</type></entry>
31235 Name of the schema the object belonged in, if any; otherwise
<literal>NULL
</literal>.
31236 No quoting is applied.
31240 <entry><literal>object_name
</literal></entry>
31241 <entry><type>text
</type></entry>
31243 Name of the object, if the combination of schema and name can be
31244 used as a unique identifier for the object; otherwise
<literal>NULL
</literal>.
31245 No quoting is applied, and name is never schema-qualified.
31249 <entry><literal>object_identity
</literal></entry>
31250 <entry><type>text
</type></entry>
31252 Text rendering of the object identity, schema-qualified. Each
31253 identifier included in the identity is quoted if necessary.
31257 <entry><literal>address_names
</literal></entry>
31258 <entry><type>text[]
</type></entry>
31260 An array that, together with
<literal>object_type
</literal> and
31261 <literal>address_args
</literal>, can be used by
31262 the
<function>pg_get_object_address
</function> function to
31263 recreate the object address in a remote server containing an
31264 identically named object of the same kind.
31268 <entry><literal>address_args
</literal></entry>
31269 <entry><type>text[]
</type></entry>
31271 Complement for
<literal>address_names
</literal>
31280 The
<function>pg_event_trigger_dropped_objects
</function> function can be used
31281 in an event trigger like this:
31283 CREATE FUNCTION test_event_trigger_for_drops()
31284 RETURNS event_trigger LANGUAGE plpgsql AS $$
31288 FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
31290 RAISE NOTICE '% dropped object: % %.% %',
31295 obj.object_identity;
31299 CREATE EVENT TRIGGER test_event_trigger_for_drops
31301 EXECUTE FUNCTION test_event_trigger_for_drops();
31306 <sect2 id=
"pg-event-trigger-table-rewrite-functions">
31307 <title>Handling a Table Rewrite Event
</title>
31310 The functions shown in
31311 <xref linkend=
"functions-event-trigger-table-rewrite"/>
31312 provide information about a table for which a
31313 <literal>table_rewrite
</literal> event has just been called.
31314 If called in any other context, an error is raised.
31317 <table id=
"functions-event-trigger-table-rewrite">
31318 <title>Table Rewrite Information Functions
</title>
31322 <entry role=
"func_table_entry"><para role=
"func_signature">
31333 <entry role=
"func_table_entry"><para role=
"func_signature">
31335 <primary>pg_event_trigger_table_rewrite_oid
</primary>
31337 <function>pg_event_trigger_table_rewrite_oid
</function> ()
31338 <returnvalue>oid
</returnvalue>
31341 Returns the OID of the table about to be rewritten.
31346 <entry role=
"func_table_entry"><para role=
"func_signature">
31348 <primary>pg_event_trigger_table_rewrite_reason
</primary>
31350 <function>pg_event_trigger_table_rewrite_reason
</function> ()
31351 <returnvalue>integer
</returnvalue>
31354 Returns a code explaining the reason(s) for rewriting. The exact
31355 meaning of the codes is release dependent.
31363 These functions can be used in an event trigger like this:
31365 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
31366 RETURNS event_trigger
31367 LANGUAGE plpgsql AS
31370 RAISE NOTICE 'rewriting table % for reason %',
31371 pg_event_trigger_table_rewrite_oid()::regclass,
31372 pg_event_trigger_table_rewrite_reason();
31376 CREATE EVENT TRIGGER test_table_rewrite_oid
31378 EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
31384 <sect1 id=
"functions-statistics">
31385 <title>Statistics Information Functions
</title>
31387 <indexterm zone=
"functions-statistics">
31388 <primary>function
</primary>
31389 <secondary>statistics
</secondary>
31393 <productname>PostgreSQL
</productname> provides a function to inspect complex
31394 statistics defined using the
<command>CREATE STATISTICS
</command> command.
31397 <sect2 id=
"functions-statistics-mcv">
31398 <title>Inspecting MCV Lists
</title>
31401 <primary>pg_mcv_list_items
</primary>
31405 <function>pg_mcv_list_items
</function> (
<type>pg_mcv_list
</type> )
<returnvalue>setof record
</returnvalue>
31409 <function>pg_mcv_list_items
</function> returns a set of records describing
31410 all items stored in a multi-column
<acronym>MCV
</acronym> list. It
31411 returns the following columns:
31417 <entry>Name
</entry>
31418 <entry>Type
</entry>
31419 <entry>Description
</entry>
31425 <entry><literal>index
</literal></entry>
31426 <entry><type>integer
</type></entry>
31427 <entry>index of the item in the
<acronym>MCV
</acronym> list
</entry>
31430 <entry><literal>values
</literal></entry>
31431 <entry><type>text[]
</type></entry>
31432 <entry>values stored in the MCV item
</entry>
31435 <entry><literal>nulls
</literal></entry>
31436 <entry><type>boolean[]
</type></entry>
31437 <entry>flags identifying
<literal>NULL
</literal> values
</entry>
31440 <entry><literal>frequency
</literal></entry>
31441 <entry><type>double precision
</type></entry>
31442 <entry>frequency of this
<acronym>MCV
</acronym> item
</entry>
31445 <entry><literal>base_frequency
</literal></entry>
31446 <entry><type>double precision
</type></entry>
31447 <entry>base frequency of this
<acronym>MCV
</acronym> item
</entry>
31455 The
<function>pg_mcv_list_items
</function> function can be used like this:
31458 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
31459 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
31462 Values of the
<type>pg_mcv_list
</type> type can be obtained only from the
31463 <structname>pg_statistic_ext_data
</structname>.
<structfield>stxdmcv
</structfield>