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 <optional>,
<parameter>val2
</parameter> <type>"any"</type> <optional>, ...
</optional> </optional> )
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 <optional>,
<parameter>val2
</parameter> <type>"any"</type> <optional>, ...
</optional> </optional> )
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 <optional>,
<parameter>formatarg
</parameter> <type>"any"</type> <optional>, ...
</optional> </optional> )
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 <optional>,
<parameter>strict_mode
</parameter> <type>boolean
</type> <literal>DEFAULT
</literal> <literal>true
</literal> </optional> )
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 <optional>,
<parameter>start
</parameter> <type>integer
</type>
3313 <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> </optional> )
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 <optional>,
<parameter>start
</parameter> <type>integer
</type>
3335 <optional>,
<parameter>N
</parameter> <type>integer
</type>
3336 <optional>,
<parameter>endoption
</parameter> <type>integer
</type>
3337 <optional>,
<parameter>flags
</parameter> <type>text
</type>
3338 <optional>,
<parameter>subexpr
</parameter> <type>integer
</type> </optional> </optional> </optional> </optional> </optional> )
3339 <returnvalue>integer
</returnvalue>
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 <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> )
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> <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> )
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> <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> )
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> <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> )
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> <optional>,
<parameter>flags
</parameter> <type>text
</type> </optional> )
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 <optional>,
<parameter>start
</parameter> <type>integer
</type>
3520 <optional>,
<parameter>N
</parameter> <type>integer
</type>
3521 <optional>,
<parameter>flags
</parameter> <type>text
</type>
3522 <optional>,
<parameter>subexpr
</parameter> <type>integer
</type> </optional> </optional> </optional> </optional> )
3523 <returnvalue>text
</returnvalue>
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> <optional>,
<parameter>formatarg
</parameter> <type>"any"</type> <optional>, ...
</optional> </optional>)
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 The
<literal>V
</literal> can be thought of as marking the position
8743 of an implicit decimal point in the input or output string.
8744 <function>to_char
</function> and
<function>to_number
</function>
8745 do not support the use of
8746 <literal>V
</literal> combined with a decimal point
8747 (e.g.,
<literal>99.9V99
</literal> is not allowed).
8753 <literal>EEEE
</literal> (scientific notation) cannot be used in
8754 combination with any of the other formatting patterns or
8755 modifiers other than digit and decimal point patterns, and must be at the end of the format string
8756 (e.g.,
<literal>9.99EEEE
</literal> is a valid pattern).
8763 Certain modifiers can be applied to any template pattern to alter its
8764 behavior. For example,
<literal>FM99.99
</literal>
8765 is the
<literal>99.99</literal> pattern with the
8766 <literal>FM
</literal> modifier.
8767 <xref linkend=
"functions-formatting-numericmod-table"/> shows the
8768 modifier patterns for numeric formatting.
8771 <table id=
"functions-formatting-numericmod-table">
8772 <title>Template Pattern Modifiers for Numeric Formatting
</title>
8776 <entry>Modifier
</entry>
8777 <entry>Description
</entry>
8778 <entry>Example
</entry>
8783 <entry><literal>FM
</literal> prefix
</entry>
8784 <entry>fill mode (suppress trailing zeroes and padding blanks)
</entry>
8785 <entry><literal>FM99.99
</literal></entry>
8788 <entry><literal>TH
</literal> suffix
</entry>
8789 <entry>upper case ordinal number suffix
</entry>
8790 <entry><literal>999TH
</literal></entry>
8793 <entry><literal>th
</literal> suffix
</entry>
8794 <entry>lower case ordinal number suffix
</entry>
8795 <entry><literal>999th
</literal></entry>
8802 <xref linkend=
"functions-formatting-examples-table"/> shows some
8803 examples of the use of the
<function>to_char
</function> function.
8806 <table id=
"functions-formatting-examples-table">
8807 <title><function>to_char
</function> Examples
</title>
8811 <entry>Expression
</entry>
8812 <entry>Result
</entry>
8817 <entry><literal>to_char(current_timestamp, 'Day,
DD
HH12:MI:SS')
</literal></entry>
8818 <entry><literal>'Tuesday
,
06 05:
39:
18'
</literal></entry>
8821 <entry><literal>to_char(current_timestamp, 'FMDay,
FMDD
HH12:MI:SS')
</literal></entry>
8822 <entry><literal>'Tuesday,
6 05:
39:
18'
</literal></entry>
8825 <entry><literal>to_char(current_timestamp AT TIME ZONE
8826 'UTC', 'YYYY-MM-DD
"T"HH24:MI:SS
"Z"')
</literal></entry>
8827 <entry><literal>'
2022-
12-
06T05:
39:
18Z'
</literal>,
8828 <acronym>ISO
</acronym> 8601 extended format
</entry>
8831 <entry><literal>to_char(-
0.1, '
99.99')
</literal></entry>
8832 <entry><literal>'
-
.10'
</literal></entry>
8835 <entry><literal>to_char(-
0.1, 'FM9.99')
</literal></entry>
8836 <entry><literal>'-
.1'
</literal></entry>
8839 <entry><literal>to_char(-
0.1, 'FM90.99')
</literal></entry>
8840 <entry><literal>'-
0.1'
</literal></entry>
8843 <entry><literal>to_char(
0.1, '
0.9')
</literal></entry>
8844 <entry><literal>'
0.1'
</literal></entry>
8847 <entry><literal>to_char(
12, '
9990999.9')
</literal></entry>
8848 <entry><literal>'
0012.0'
</literal></entry>
8851 <entry><literal>to_char(
12, 'FM9990999.9')
</literal></entry>
8852 <entry><literal>'
0012.'
</literal></entry>
8855 <entry><literal>to_char(
485, '
999')
</literal></entry>
8856 <entry><literal>'
485'
</literal></entry>
8859 <entry><literal>to_char(-
485, '
999')
</literal></entry>
8860 <entry><literal>'-
485'
</literal></entry>
8863 <entry><literal>to_char(
485, '
9 9 9')
</literal></entry>
8864 <entry><literal>'
4 8 5'
</literal></entry>
8867 <entry><literal>to_char(
1485, '
9,
999')
</literal></entry>
8868 <entry><literal>'
1,
485'
</literal></entry>
8871 <entry><literal>to_char(
1485, '
9G999')
</literal></entry>
8872 <entry><literal>'
1 485'
</literal></entry>
8875 <entry><literal>to_char(
148.5, '
999.999')
</literal></entry>
8876 <entry><literal>'
148.500'
</literal></entry>
8879 <entry><literal>to_char(
148.5, 'FM999.999')
</literal></entry>
8880 <entry><literal>'
148.5'
</literal></entry>
8883 <entry><literal>to_char(
148.5, 'FM999.990')
</literal></entry>
8884 <entry><literal>'
148.500'
</literal></entry>
8887 <entry><literal>to_char(
148.5, '
999D999')
</literal></entry>
8888 <entry><literal>'
148,
500'
</literal></entry>
8891 <entry><literal>to_char(
3148.5, '
9G999D999')
</literal></entry>
8892 <entry><literal>'
3 148,
500'
</literal></entry>
8895 <entry><literal>to_char(-
485, '
999S')
</literal></entry>
8896 <entry><literal>'
485-'
</literal></entry>
8899 <entry><literal>to_char(-
485, '
999MI')
</literal></entry>
8900 <entry><literal>'
485-'
</literal></entry>
8903 <entry><literal>to_char(
485, '
999MI')
</literal></entry>
8904 <entry><literal>'
485 '
</literal></entry>
8907 <entry><literal>to_char(
485, 'FM999MI')
</literal></entry>
8908 <entry><literal>'
485'
</literal></entry>
8911 <entry><literal>to_char(
485, 'PL999')
</literal></entry>
8912 <entry><literal>'+
485'
</literal></entry>
8915 <entry><literal>to_char(
485, 'SG999')
</literal></entry>
8916 <entry><literal>'+
485'
</literal></entry>
8919 <entry><literal>to_char(-
485, 'SG999')
</literal></entry>
8920 <entry><literal>'-
485'
</literal></entry>
8923 <entry><literal>to_char(-
485, '
9SG99')
</literal></entry>
8924 <entry><literal>'
4-
85'
</literal></entry>
8927 <entry><literal>to_char(-
485, '
999PR')
</literal></entry>
8928 <entry><literal>'
<485>'
</literal></entry>
8931 <entry><literal>to_char(
485, 'L999')
</literal></entry>
8932 <entry><literal>'DM
485'
</literal></entry>
8935 <entry><literal>to_char(
485, 'RN')
</literal></entry>
8936 <entry><literal>'
CDLXXXV'
</literal></entry>
8939 <entry><literal>to_char(
485, 'FMRN')
</literal></entry>
8940 <entry><literal>'CDLXXXV'
</literal></entry>
8943 <entry><literal>to_char(
5.2, 'FMRN')
</literal></entry>
8944 <entry><literal>'V'
</literal></entry>
8947 <entry><literal>to_char(
482, '
999th')
</literal></entry>
8948 <entry><literal>'
482nd'
</literal></entry>
8951 <entry><literal>to_char(
485, '
"Good number:"999')
</literal></entry>
8952 <entry><literal>'Good
number:
485'
</literal></entry>
8955 <entry><literal>to_char(
485.8, '
"Pre:"999" Post:" .999')
</literal></entry>
8956 <entry><literal>'Pre:
485 Post:
.800'
</literal></entry>
8959 <entry><literal>to_char(
12, '
99V999')
</literal></entry>
8960 <entry><literal>'
12000'
</literal></entry>
8963 <entry><literal>to_char(
12.4, '
99V999')
</literal></entry>
8964 <entry><literal>'
12400'
</literal></entry>
8967 <entry><literal>to_char(
12.45, '
99V9')
</literal></entry>
8968 <entry><literal>'
125'
</literal></entry>
8971 <entry><literal>to_char(
0.0004859, '
9.99EEEE')
</literal></entry>
8972 <entry><literal>'
4.86e-04'
</literal></entry>
8981 <sect1 id=
"functions-datetime">
8982 <title>Date/Time Functions and Operators
</title>
8985 <xref linkend=
"functions-datetime-table"/> shows the available
8986 functions for date/time value processing, with details appearing in
8987 the following subsections.
<xref
8988 linkend=
"operators-datetime-table"/> illustrates the behaviors of
8989 the basic arithmetic operators (
<literal>+
</literal>,
8990 <literal>*
</literal>, etc.). For formatting functions, refer to
8991 <xref linkend=
"functions-formatting"/>. You should be familiar with
8992 the background information on date/time data types from
<xref
8993 linkend=
"datatype-datetime"/>.
8997 In addition, the usual comparison operators shown in
8998 <xref linkend=
"functions-comparison-op-table"/> are available for the
8999 date/time types. Dates and timestamps (with or without time zone) are
9000 all comparable, while times (with or without time zone) and intervals
9001 can only be compared to other values of the same data type. When
9002 comparing a timestamp without time zone to a timestamp with time zone,
9003 the former value is assumed to be given in the time zone specified by
9004 the
<xref linkend=
"guc-timezone"/> configuration parameter, and is
9005 rotated to UTC for comparison to the latter value (which is already
9006 in UTC internally). Similarly, a date value is assumed to represent
9007 midnight in the
<varname>TimeZone
</varname> zone when comparing it
9012 All the functions and operators described below that take
<type>time
</type> or
<type>timestamp
</type>
9013 inputs actually come in two variants: one that takes
<type>time with time zone
</type> or
<type>timestamp
9014 with time zone
</type>, and one that takes
<type>time without time zone
</type> or
<type>timestamp without time zone
</type>.
9015 For brevity, these variants are not shown separately. Also, the
9016 <literal>+
</literal> and
<literal>*
</literal> operators come in commutative pairs (for
9017 example both
<type>date
</type> <literal>+
</literal> <type>integer
</type>
9018 and
<type>integer
</type> <literal>+
</literal> <type>date
</type>); we show
9019 only one of each such pair.
9022 <table id=
"operators-datetime-table">
9023 <title>Date/Time Operators
</title>
9028 <entry role=
"func_table_entry"><para role=
"func_signature">
9042 <entry role=
"func_table_entry"><para role=
"func_signature">
9043 <type>date
</type> <literal>+
</literal> <type>integer
</type>
9044 <returnvalue>date
</returnvalue>
9047 Add a number of days to a date
9050 <literal>date '
2001-
09-
28' +
7</literal>
9051 <returnvalue>2001-
10-
05</returnvalue>
9056 <entry role=
"func_table_entry"><para role=
"func_signature">
9057 <type>date
</type> <literal>+
</literal> <type>interval
</type>
9058 <returnvalue>timestamp
</returnvalue>
9061 Add an interval to a date
9064 <literal>date '
2001-
09-
28' + interval '
1 hour'
</literal>
9065 <returnvalue>2001-
09-
28 01:
00:
00</returnvalue>
9070 <entry role=
"func_table_entry"><para role=
"func_signature">
9071 <type>date
</type> <literal>+
</literal> <type>time
</type>
9072 <returnvalue>timestamp
</returnvalue>
9075 Add a time-of-day to a date
9078 <literal>date '
2001-
09-
28' + time '
03:
00'
</literal>
9079 <returnvalue>2001-
09-
28 03:
00:
00</returnvalue>
9084 <entry role=
"func_table_entry"><para role=
"func_signature">
9085 <type>interval
</type> <literal>+
</literal> <type>interval
</type>
9086 <returnvalue>interval
</returnvalue>
9092 <literal>interval '
1 day' + interval '
1 hour'
</literal>
9093 <returnvalue>1 day
01:
00:
00</returnvalue>
9098 <entry role=
"func_table_entry"><para role=
"func_signature">
9099 <type>timestamp
</type> <literal>+
</literal> <type>interval
</type>
9100 <returnvalue>timestamp
</returnvalue>
9103 Add an interval to a timestamp
9106 <literal>timestamp '
2001-
09-
28 01:
00' + interval '
23 hours'
</literal>
9107 <returnvalue>2001-
09-
29 00:
00:
00</returnvalue>
9112 <entry role=
"func_table_entry"><para role=
"func_signature">
9113 <type>time
</type> <literal>+
</literal> <type>interval
</type>
9114 <returnvalue>time
</returnvalue>
9117 Add an interval to a time
9120 <literal>time '
01:
00' + interval '
3 hours'
</literal>
9121 <returnvalue>04:
00:
00</returnvalue>
9126 <entry role=
"func_table_entry"><para role=
"func_signature">
9127 <literal>-
</literal> <type>interval
</type>
9128 <returnvalue>interval
</returnvalue>
9134 <literal>- interval '
23 hours'
</literal>
9135 <returnvalue>-
23:
00:
00</returnvalue>
9140 <entry role=
"func_table_entry"><para role=
"func_signature">
9141 <type>date
</type> <literal>-
</literal> <type>date
</type>
9142 <returnvalue>integer
</returnvalue>
9145 Subtract dates, producing the number of days elapsed
9148 <literal>date '
2001-
10-
01' - date '
2001-
09-
28'
</literal>
9149 <returnvalue>3</returnvalue>
9154 <entry role=
"func_table_entry"><para role=
"func_signature">
9155 <type>date
</type> <literal>-
</literal> <type>integer
</type>
9156 <returnvalue>date
</returnvalue>
9159 Subtract a number of days from a date
9162 <literal>date '
2001-
10-
01' -
7</literal>
9163 <returnvalue>2001-
09-
24</returnvalue>
9168 <entry role=
"func_table_entry"><para role=
"func_signature">
9169 <type>date
</type> <literal>-
</literal> <type>interval
</type>
9170 <returnvalue>timestamp
</returnvalue>
9173 Subtract an interval from a date
9176 <literal>date '
2001-
09-
28' - interval '
1 hour'
</literal>
9177 <returnvalue>2001-
09-
27 23:
00:
00</returnvalue>
9182 <entry role=
"func_table_entry"><para role=
"func_signature">
9183 <type>time
</type> <literal>-
</literal> <type>time
</type>
9184 <returnvalue>interval
</returnvalue>
9190 <literal>time '
05:
00' - time '
03:
00'
</literal>
9191 <returnvalue>02:
00:
00</returnvalue>
9196 <entry role=
"func_table_entry"><para role=
"func_signature">
9197 <type>time
</type> <literal>-
</literal> <type>interval
</type>
9198 <returnvalue>time
</returnvalue>
9201 Subtract an interval from a time
9204 <literal>time '
05:
00' - interval '
2 hours'
</literal>
9205 <returnvalue>03:
00:
00</returnvalue>
9210 <entry role=
"func_table_entry"><para role=
"func_signature">
9211 <type>timestamp
</type> <literal>-
</literal> <type>interval
</type>
9212 <returnvalue>timestamp
</returnvalue>
9215 Subtract an interval from a timestamp
9218 <literal>timestamp '
2001-
09-
28 23:
00' - interval '
23 hours'
</literal>
9219 <returnvalue>2001-
09-
28 00:
00:
00</returnvalue>
9224 <entry role=
"func_table_entry"><para role=
"func_signature">
9225 <type>interval
</type> <literal>-
</literal> <type>interval
</type>
9226 <returnvalue>interval
</returnvalue>
9232 <literal>interval '
1 day' - interval '
1 hour'
</literal>
9233 <returnvalue>1 day -
01:
00:
00</returnvalue>
9238 <entry role=
"func_table_entry"><para role=
"func_signature">
9239 <type>timestamp
</type> <literal>-
</literal> <type>timestamp
</type>
9240 <returnvalue>interval
</returnvalue>
9243 Subtract timestamps (converting
24-hour intervals into days,
9245 linkend=
"function-justify-hours"><function>justify_hours()
</function></link>)
9248 <literal>timestamp '
2001-
09-
29 03:
00' - timestamp '
2001-
07-
27 12:
00'
</literal>
9249 <returnvalue>63 days
15:
00:
00</returnvalue>
9254 <entry role=
"func_table_entry"><para role=
"func_signature">
9255 <type>interval
</type> <literal>*
</literal> <type>double precision
</type>
9256 <returnvalue>interval
</returnvalue>
9259 Multiply an interval by a scalar
9262 <literal>interval '
1 second' *
900</literal>
9263 <returnvalue>00:
15:
00</returnvalue>
9266 <literal>interval '
1 day' *
21</literal>
9267 <returnvalue>21 days
</returnvalue>
9270 <literal>interval '
1 hour' *
3.5</literal>
9271 <returnvalue>03:
30:
00</returnvalue>
9276 <entry role=
"func_table_entry"><para role=
"func_signature">
9277 <type>interval
</type> <literal>/
</literal> <type>double precision
</type>
9278 <returnvalue>interval
</returnvalue>
9281 Divide an interval by a scalar
9284 <literal>interval '
1 hour' /
1.5</literal>
9285 <returnvalue>00:
40:
00</returnvalue>
9292 <table id=
"functions-datetime-table">
9293 <title>Date/Time Functions
</title>
9297 <entry role=
"func_table_entry"><para role=
"func_signature">
9311 <entry role=
"func_table_entry"><para role=
"func_signature">
9313 <primary>age
</primary>
9315 <function>age
</function> (
<type>timestamp
</type>,
<type>timestamp
</type> )
9316 <returnvalue>interval
</returnvalue>
9319 Subtract arguments, producing a
<quote>symbolic
</quote> result that
9320 uses years and months, rather than just days
9323 <literal>age(timestamp '
2001-
04-
10', timestamp '
1957-
06-
13')
</literal>
9324 <returnvalue>43 years
9 mons
27 days
</returnvalue>
9329 <entry role=
"func_table_entry"><para role=
"func_signature">
9330 <function>age
</function> (
<type>timestamp
</type> )
9331 <returnvalue>interval
</returnvalue>
9334 Subtract argument from
<function>current_date
</function> (at midnight)
9337 <literal>age(timestamp '
1957-
06-
13')
</literal>
9338 <returnvalue>62 years
6 mons
10 days
</returnvalue>
9343 <entry role=
"func_table_entry"><para role=
"func_signature">
9345 <primary>clock_timestamp
</primary>
9347 <function>clock_timestamp
</function> ( )
9348 <returnvalue>timestamp with time zone
</returnvalue>
9351 Current date and time (changes during statement execution);
9352 see
<xref linkend=
"functions-datetime-current"/>
9355 <literal>clock_timestamp()
</literal>
9356 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9361 <entry role=
"func_table_entry"><para role=
"func_signature">
9363 <primary>current_date
</primary>
9365 <function>current_date
</function>
9366 <returnvalue>date
</returnvalue>
9369 Current date; see
<xref linkend=
"functions-datetime-current"/>
9372 <literal>current_date
</literal>
9373 <returnvalue>2019-
12-
23</returnvalue>
9378 <entry role=
"func_table_entry"><para role=
"func_signature">
9380 <primary>current_time
</primary>
9382 <function>current_time
</function>
9383 <returnvalue>time with time zone
</returnvalue>
9386 Current time of day; see
<xref linkend=
"functions-datetime-current"/>
9389 <literal>current_time
</literal>
9390 <returnvalue>14:
39:
53.662522-
05</returnvalue>
9395 <entry role=
"func_table_entry"><para role=
"func_signature">
9396 <function>current_time
</function> (
<type>integer
</type> )
9397 <returnvalue>time with time zone
</returnvalue>
9400 Current time of day, with limited precision;
9401 see
<xref linkend=
"functions-datetime-current"/>
9404 <literal>current_time(
2)
</literal>
9405 <returnvalue>14:
39:
53.66-
05</returnvalue>
9410 <entry role=
"func_table_entry"><para role=
"func_signature">
9412 <primary>current_timestamp
</primary>
9414 <function>current_timestamp
</function>
9415 <returnvalue>timestamp with time zone
</returnvalue>
9418 Current date and time (start of current transaction);
9419 see
<xref linkend=
"functions-datetime-current"/>
9422 <literal>current_timestamp
</literal>
9423 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9428 <entry role=
"func_table_entry"><para role=
"func_signature">
9429 <function>current_timestamp
</function> (
<type>integer
</type> )
9430 <returnvalue>timestamp with time zone
</returnvalue>
9433 Current date and time (start of current transaction), with limited precision;
9434 see
<xref linkend=
"functions-datetime-current"/>
9437 <literal>current_timestamp(
0)
</literal>
9438 <returnvalue>2019-
12-
23 14:
39:
53-
05</returnvalue>
9443 <entry role=
"func_table_entry"><para role=
"func_signature">
9445 <primary>date_add
</primary>
9447 <function>date_add
</function> (
<type>timestamp with time zone
</type>,
<type>interval
</type> <optional>,
<type>text
</type> </optional> )
9448 <returnvalue>timestamp with time zone
</returnvalue>
9451 Add an
<type>interval
</type> to a
<type>timestamp with time
9452 zone
</type>, computing times of day and daylight-savings adjustments
9453 according to the time zone named by the third argument, or the
9454 current
<xref linkend=
"guc-timezone"/> setting if that is omitted.
9455 The form with two arguments is equivalent to the
<type>timestamp with
9456 time zone
</type> <literal>+
</literal> <type>interval
</type> operator.
9459 <literal>date_add('
2021-
10-
31 00:
00:
00+
02'::timestamptz, '
1 day'::interval, 'Europe/Warsaw')
</literal>
9460 <returnvalue>2021-
10-
31 23:
00:
00+
00</returnvalue>
9465 <entry role=
"func_table_entry"><para role=
"func_signature">
9466 <function>date_bin
</function> (
<type>interval
</type>,
<type>timestamp
</type>,
<type>timestamp
</type> )
9467 <returnvalue>timestamp
</returnvalue>
9470 Bin input into specified interval aligned with specified origin; see
<xref linkend=
"functions-datetime-bin"/>
9473 <literal>date_bin('
15 minutes', timestamp '
2001-
02-
16 20:
38:
40', timestamp '
2001-
02-
16 20:
05:
00')
</literal>
9474 <returnvalue>2001-
02-
16 20:
35:
00</returnvalue>
9479 <entry role=
"func_table_entry"><para role=
"func_signature">
9481 <primary>date_part
</primary>
9483 <function>date_part
</function> (
<type>text
</type>,
<type>timestamp
</type> )
9484 <returnvalue>double precision
</returnvalue>
9487 Get timestamp subfield (equivalent to
<function>extract
</function>);
9488 see
<xref linkend=
"functions-datetime-extract"/>
9491 <literal>date_part('hour', timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9492 <returnvalue>20</returnvalue>
9497 <entry role=
"func_table_entry"><para role=
"func_signature">
9498 <function>date_part
</function> (
<type>text
</type>,
<type>interval
</type> )
9499 <returnvalue>double precision
</returnvalue>
9502 Get interval subfield (equivalent to
<function>extract
</function>);
9503 see
<xref linkend=
"functions-datetime-extract"/>
9506 <literal>date_part('month', interval '
2 years
3 months')
</literal>
9507 <returnvalue>3</returnvalue>
9512 <entry role=
"func_table_entry"><para role=
"func_signature">
9514 <primary>date_subtract
</primary>
9516 <function>date_subtract
</function> (
<type>timestamp with time zone
</type>,
<type>interval
</type> <optional>,
<type>text
</type> </optional> )
9517 <returnvalue>timestamp with time zone
</returnvalue>
9520 Subtract an
<type>interval
</type> from a
<type>timestamp with time
9521 zone
</type>, computing times of day and daylight-savings adjustments
9522 according to the time zone named by the third argument, or the
9523 current
<xref linkend=
"guc-timezone"/> setting if that is omitted.
9524 The form with two arguments is equivalent to the
<type>timestamp with
9525 time zone
</type> <literal>-
</literal> <type>interval
</type> operator.
9528 <literal>date_subtract('
2021-
11-
01 00:
00:
00+
01'::timestamptz, '
1 day'::interval, 'Europe/Warsaw')
</literal>
9529 <returnvalue>2021-
10-
30 22:
00:
00+
00</returnvalue>
9534 <entry role=
"func_table_entry"><para role=
"func_signature">
9536 <primary>date_trunc
</primary>
9538 <function>date_trunc
</function> (
<type>text
</type>,
<type>timestamp
</type> )
9539 <returnvalue>timestamp
</returnvalue>
9542 Truncate to specified precision; see
<xref linkend=
"functions-datetime-trunc"/>
9545 <literal>date_trunc('hour', timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9546 <returnvalue>2001-
02-
16 20:
00:
00</returnvalue>
9551 <entry role=
"func_table_entry"><para role=
"func_signature">
9552 <function>date_trunc
</function> (
<type>text
</type>,
<type>timestamp with time zone
</type>,
<type>text
</type> )
9553 <returnvalue>timestamp with time zone
</returnvalue>
9556 Truncate to specified precision in the specified time zone; see
9557 <xref linkend=
"functions-datetime-trunc"/>
9560 <literal>date_trunc('day', timestamptz '
2001-
02-
16 20:
38:
40+
00', 'Australia/Sydney')
</literal>
9561 <returnvalue>2001-
02-
16 13:
00:
00+
00</returnvalue>
9566 <entry role=
"func_table_entry"><para role=
"func_signature">
9567 <function>date_trunc
</function> (
<type>text
</type>,
<type>interval
</type> )
9568 <returnvalue>interval
</returnvalue>
9571 Truncate to specified precision; see
9572 <xref linkend=
"functions-datetime-trunc"/>
9575 <literal>date_trunc('hour', interval '
2 days
3 hours
40 minutes')
</literal>
9576 <returnvalue>2 days
03:
00:
00</returnvalue>
9581 <entry role=
"func_table_entry"><para role=
"func_signature">
9583 <primary>extract
</primary>
9585 <function>extract
</function> (
<parameter>field
</parameter> <literal>from
</literal> <type>timestamp
</type> )
9586 <returnvalue>numeric
</returnvalue>
9589 Get timestamp subfield; see
<xref linkend=
"functions-datetime-extract"/>
9592 <literal>extract(hour from timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9593 <returnvalue>20</returnvalue>
9598 <entry role=
"func_table_entry"><para role=
"func_signature">
9599 <function>extract
</function> (
<parameter>field
</parameter> <literal>from
</literal> <type>interval
</type> )
9600 <returnvalue>numeric
</returnvalue>
9603 Get interval subfield; see
<xref linkend=
"functions-datetime-extract"/>
9606 <literal>extract(month from interval '
2 years
3 months')
</literal>
9607 <returnvalue>3</returnvalue>
9612 <entry role=
"func_table_entry"><para role=
"func_signature">
9614 <primary>isfinite
</primary>
9616 <function>isfinite
</function> (
<type>date
</type> )
9617 <returnvalue>boolean
</returnvalue>
9620 Test for finite date (not +/-infinity)
9623 <literal>isfinite(date '
2001-
02-
16')
</literal>
9624 <returnvalue>true
</returnvalue>
9629 <entry role=
"func_table_entry"><para role=
"func_signature">
9630 <function>isfinite
</function> (
<type>timestamp
</type> )
9631 <returnvalue>boolean
</returnvalue>
9634 Test for finite timestamp (not +/-infinity)
9637 <literal>isfinite(timestamp 'infinity')
</literal>
9638 <returnvalue>false
</returnvalue>
9643 <entry role=
"func_table_entry"><para role=
"func_signature">
9644 <function>isfinite
</function> (
<type>interval
</type> )
9645 <returnvalue>boolean
</returnvalue>
9648 Test for finite interval (not +/-infinity)
9651 <literal>isfinite(interval '
4 hours')
</literal>
9652 <returnvalue>true
</returnvalue>
9657 <entry role=
"func_table_entry"><para role=
"func_signature">
9658 <indexterm id=
"function-justify-days">
9659 <primary>justify_days
</primary>
9661 <function>justify_days
</function> (
<type>interval
</type> )
9662 <returnvalue>interval
</returnvalue>
9665 Adjust interval, converting
30-day time periods to months
9668 <literal>justify_days(interval '
1 year
65 days')
</literal>
9669 <returnvalue>1 year
2 mons
5 days
</returnvalue>
9674 <entry role=
"func_table_entry"><para role=
"func_signature">
9675 <indexterm id=
"function-justify-hours">
9676 <primary>justify_hours
</primary>
9678 <function>justify_hours
</function> (
<type>interval
</type> )
9679 <returnvalue>interval
</returnvalue>
9682 Adjust interval, converting
24-hour time periods to days
9685 <literal>justify_hours(interval '
50 hours
10 minutes')
</literal>
9686 <returnvalue>2 days
02:
10:
00</returnvalue>
9691 <entry role=
"func_table_entry"><para role=
"func_signature">
9693 <primary>justify_interval
</primary>
9695 <function>justify_interval
</function> (
<type>interval
</type> )
9696 <returnvalue>interval
</returnvalue>
9699 Adjust interval using
<function>justify_days
</function>
9700 and
<function>justify_hours
</function>, with additional sign
9704 <literal>justify_interval(interval '
1 mon -
1 hour')
</literal>
9705 <returnvalue>29 days
23:
00:
00</returnvalue>
9710 <entry role=
"func_table_entry"><para role=
"func_signature">
9712 <primary>localtime
</primary>
9714 <function>localtime
</function>
9715 <returnvalue>time
</returnvalue>
9718 Current time of day;
9719 see
<xref linkend=
"functions-datetime-current"/>
9722 <literal>localtime
</literal>
9723 <returnvalue>14:
39:
53.662522</returnvalue>
9728 <entry role=
"func_table_entry"><para role=
"func_signature">
9729 <function>localtime
</function> (
<type>integer
</type> )
9730 <returnvalue>time
</returnvalue>
9733 Current time of day, with limited precision;
9734 see
<xref linkend=
"functions-datetime-current"/>
9737 <literal>localtime(
0)
</literal>
9738 <returnvalue>14:
39:
53</returnvalue>
9743 <entry role=
"func_table_entry"><para role=
"func_signature">
9745 <primary>localtimestamp
</primary>
9747 <function>localtimestamp
</function>
9748 <returnvalue>timestamp
</returnvalue>
9751 Current date and time (start of current transaction);
9752 see
<xref linkend=
"functions-datetime-current"/>
9755 <literal>localtimestamp
</literal>
9756 <returnvalue>2019-
12-
23 14:
39:
53.662522</returnvalue>
9761 <entry role=
"func_table_entry"><para role=
"func_signature">
9762 <function>localtimestamp
</function> (
<type>integer
</type> )
9763 <returnvalue>timestamp
</returnvalue>
9766 Current date and time (start of current
9767 transaction), with limited precision;
9768 see
<xref linkend=
"functions-datetime-current"/>
9771 <literal>localtimestamp(
2)
</literal>
9772 <returnvalue>2019-
12-
23 14:
39:
53.66</returnvalue>
9777 <entry role=
"func_table_entry"><para role=
"func_signature">
9779 <primary>make_date
</primary>
9781 <function>make_date
</function> (
<parameter>year
</parameter> <type>int
</type>,
9782 <parameter>month
</parameter> <type>int
</type>,
9783 <parameter>day
</parameter> <type>int
</type> )
9784 <returnvalue>date
</returnvalue>
9787 Create date from year, month and day fields
9788 (negative years signify BC)
9791 <literal>make_date(
2013,
7,
15)
</literal>
9792 <returnvalue>2013-
07-
15</returnvalue>
9797 <entry role=
"func_table_entry"><para role=
"func_signature"><indexterm>
9798 <primary>make_interval
</primary>
9800 <function>make_interval
</function> (
<optional> <parameter>years
</parameter> <type>int
</type>
9801 <optional>,
<parameter>months
</parameter> <type>int
</type>
9802 <optional>,
<parameter>weeks
</parameter> <type>int
</type>
9803 <optional>,
<parameter>days
</parameter> <type>int
</type>
9804 <optional>,
<parameter>hours
</parameter> <type>int
</type>
9805 <optional>,
<parameter>mins
</parameter> <type>int
</type>
9806 <optional>,
<parameter>secs
</parameter> <type>double precision
</type>
9807 </optional></optional></optional></optional></optional></optional></optional> )
9808 <returnvalue>interval
</returnvalue>
9811 Create interval from years, months, weeks, days, hours, minutes and
9812 seconds fields, each of which can default to zero
9815 <literal>make_interval(days =
> 10)
</literal>
9816 <returnvalue>10 days
</returnvalue>
9821 <entry role=
"func_table_entry"><para role=
"func_signature">
9823 <primary>make_time
</primary>
9825 <function>make_time
</function> (
<parameter>hour
</parameter> <type>int
</type>,
9826 <parameter>min
</parameter> <type>int
</type>,
9827 <parameter>sec
</parameter> <type>double precision
</type> )
9828 <returnvalue>time
</returnvalue>
9831 Create time from hour, minute and seconds fields
9834 <literal>make_time(
8,
15,
23.5)
</literal>
9835 <returnvalue>08:
15:
23.5</returnvalue>
9840 <entry role=
"func_table_entry"><para role=
"func_signature">
9842 <primary>make_timestamp
</primary>
9844 <function>make_timestamp
</function> (
<parameter>year
</parameter> <type>int
</type>,
9845 <parameter>month
</parameter> <type>int
</type>,
9846 <parameter>day
</parameter> <type>int
</type>,
9847 <parameter>hour
</parameter> <type>int
</type>,
9848 <parameter>min
</parameter> <type>int
</type>,
9849 <parameter>sec
</parameter> <type>double precision
</type> )
9850 <returnvalue>timestamp
</returnvalue>
9853 Create timestamp from year, month, day, hour, minute and seconds fields
9854 (negative years signify BC)
9857 <literal>make_timestamp(
2013,
7,
15,
8,
15,
23.5)
</literal>
9858 <returnvalue>2013-
07-
15 08:
15:
23.5</returnvalue>
9863 <entry role=
"func_table_entry"><para role=
"func_signature">
9865 <primary>make_timestamptz
</primary>
9867 <function>make_timestamptz
</function> (
<parameter>year
</parameter> <type>int
</type>,
9868 <parameter>month
</parameter> <type>int
</type>,
9869 <parameter>day
</parameter> <type>int
</type>,
9870 <parameter>hour
</parameter> <type>int
</type>,
9871 <parameter>min
</parameter> <type>int
</type>,
9872 <parameter>sec
</parameter> <type>double precision
</type>
9873 <optional>,
<parameter>timezone
</parameter> <type>text
</type> </optional> )
9874 <returnvalue>timestamp with time zone
</returnvalue>
9877 Create timestamp with time zone from year, month, day, hour, minute
9878 and seconds fields (negative years signify BC).
9879 If
<parameter>timezone
</parameter> is not
9880 specified, the current time zone is used; the examples assume the
9881 session time zone is
<literal>Europe/London
</literal>
9884 <literal>make_timestamptz(
2013,
7,
15,
8,
15,
23.5)
</literal>
9885 <returnvalue>2013-
07-
15 08:
15:
23.5+
01</returnvalue>
9888 <literal>make_timestamptz(
2013,
7,
15,
8,
15,
23.5, 'America/New_York')
</literal>
9889 <returnvalue>2013-
07-
15 13:
15:
23.5+
01</returnvalue>
9894 <entry role=
"func_table_entry"><para role=
"func_signature">
9896 <primary>now
</primary>
9898 <function>now
</function> ( )
9899 <returnvalue>timestamp with time zone
</returnvalue>
9902 Current date and time (start of current transaction);
9903 see
<xref linkend=
"functions-datetime-current"/>
9906 <literal>now()
</literal>
9907 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9912 <entry role=
"func_table_entry"><para role=
"func_signature">
9914 <primary>statement_timestamp
</primary>
9916 <function>statement_timestamp
</function> ( )
9917 <returnvalue>timestamp with time zone
</returnvalue>
9920 Current date and time (start of current statement);
9921 see
<xref linkend=
"functions-datetime-current"/>
9924 <literal>statement_timestamp()
</literal>
9925 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9930 <entry role=
"func_table_entry"><para role=
"func_signature">
9932 <primary>timeofday
</primary>
9934 <function>timeofday
</function> ( )
9935 <returnvalue>text
</returnvalue>
9938 Current date and time
9939 (like
<function>clock_timestamp
</function>, but as a
<type>text
</type> string);
9940 see
<xref linkend=
"functions-datetime-current"/>
9943 <literal>timeofday()
</literal>
9944 <returnvalue>Mon Dec
23 14:
39:
53.662522 2019 EST
</returnvalue>
9949 <entry role=
"func_table_entry"><para role=
"func_signature">
9951 <primary>transaction_timestamp
</primary>
9953 <function>transaction_timestamp
</function> ( )
9954 <returnvalue>timestamp with time zone
</returnvalue>
9957 Current date and time (start of current transaction);
9958 see
<xref linkend=
"functions-datetime-current"/>
9961 <literal>transaction_timestamp()
</literal>
9962 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9967 <entry role=
"func_table_entry"><para role=
"func_signature">
9969 <primary>to_timestamp
</primary>
9971 <function>to_timestamp
</function> (
<type>double precision
</type> )
9972 <returnvalue>timestamp with time zone
</returnvalue>
9975 Convert Unix epoch (seconds since
1970-
01-
01 00:
00:
00+
00) to
9976 timestamp with time zone
9979 <literal>to_timestamp(
1284352323)
</literal>
9980 <returnvalue>2010-
09-
13 04:
32:
03+
00</returnvalue>
9989 <primary>OVERLAPS
</primary>
9991 In addition to these functions, the SQL
<literal>OVERLAPS
</literal> operator is
9994 (
<replaceable>start1
</replaceable>,
<replaceable>end1
</replaceable>) OVERLAPS (
<replaceable>start2
</replaceable>,
<replaceable>end2
</replaceable>)
9995 (
<replaceable>start1
</replaceable>,
<replaceable>length1
</replaceable>) OVERLAPS (
<replaceable>start2
</replaceable>,
<replaceable>length2
</replaceable>)
9997 This expression yields true when two time periods (defined by their
9998 endpoints) overlap, false when they do not overlap. The endpoints
9999 can be specified as pairs of dates, times, or time stamps; or as
10000 a date, time, or time stamp followed by an interval. When a pair
10001 of values is provided, either the start or the end can be written
10002 first;
<literal>OVERLAPS
</literal> automatically takes the earlier value
10003 of the pair as the start. Each time period is considered to
10004 represent the half-open interval
<replaceable>start
</replaceable> <literal><=
</literal>
10005 <replaceable>time
</replaceable> <literal><</literal> <replaceable>end
</replaceable>, unless
10006 <replaceable>start
</replaceable> and
<replaceable>end
</replaceable> are equal in which case it
10007 represents that single time instant. This means for instance that two
10008 time periods with only an endpoint in common do not overlap.
10012 SELECT (DATE '
2001-
02-
16', DATE '
2001-
12-
21') OVERLAPS
10013 (DATE '
2001-
10-
30', DATE '
2002-
10-
30');
10014 <lineannotation>Result:
</lineannotation><computeroutput>true
</computeroutput>
10015 SELECT (DATE '
2001-
02-
16', INTERVAL '
100 days') OVERLAPS
10016 (DATE '
2001-
10-
30', DATE '
2002-
10-
30');
10017 <lineannotation>Result:
</lineannotation><computeroutput>false
</computeroutput>
10018 SELECT (DATE '
2001-
10-
29', DATE '
2001-
10-
30') OVERLAPS
10019 (DATE '
2001-
10-
30', DATE '
2001-
10-
31');
10020 <lineannotation>Result:
</lineannotation><computeroutput>false
</computeroutput>
10021 SELECT (DATE '
2001-
10-
30', DATE '
2001-
10-
30') OVERLAPS
10022 (DATE '
2001-
10-
30', DATE '
2001-
10-
31');
10023 <lineannotation>Result:
</lineannotation><computeroutput>true
</computeroutput>
10027 When adding an
<type>interval
</type> value to (or subtracting an
10028 <type>interval
</type> value from) a
<type>timestamp
</type>
10029 or
<type>timestamp with time zone
</type> value, the months, days, and
10030 microseconds fields of the
<type>interval
</type> value are handled in turn.
10031 First, a nonzero months field advances or decrements the date of the
10032 timestamp by the indicated number of months, keeping the day of month the
10033 same unless it would be past the end of the new month, in which case the
10034 last day of that month is used. (For example, March
31 plus
1 month
10035 becomes April
30, but March
31 plus
2 months becomes May
31.)
10036 Then the days field advances or decrements the date of the timestamp by
10037 the indicated number of days. In both these steps the local time of day
10038 is kept the same. Finally, if there is a nonzero microseconds field, it
10039 is added or subtracted literally.
10040 When doing arithmetic on a
<type>timestamp with time zone
</type> value in
10041 a time zone that recognizes DST, this means that adding or subtracting
10042 (say)
<literal>interval '
1 day'
</literal> does not necessarily have the
10043 same result as adding or subtracting
<literal>interval '
24
10045 For example, with the session time zone set
10046 to
<literal>America/Denver
</literal>:
10048 SELECT timestamp with time zone '
2005-
04-
02 12:
00:
00-
07' + interval '
1 day';
10049 <lineannotation>Result:
</lineannotation><computeroutput>2005-
04-
03 12:
00:
00-
06</computeroutput>
10050 SELECT timestamp with time zone '
2005-
04-
02 12:
00:
00-
07' + interval '
24 hours';
10051 <lineannotation>Result:
</lineannotation><computeroutput>2005-
04-
03 13:
00:
00-
06</computeroutput>
10053 This happens because an hour was skipped due to a change in daylight saving
10054 time at
<literal>2005-
04-
03 02:
00:
00</literal> in time zone
10055 <literal>America/Denver
</literal>.
10059 Note there can be ambiguity in the
<literal>months
</literal> field returned by
10060 <function>age
</function> because different months have different numbers of
10061 days.
<productname>PostgreSQL
</productname>'s approach uses the month from the
10062 earlier of the two dates when calculating partial months. For example,
10063 <literal>age('
2004-
06-
01', '
2004-
04-
30')
</literal> uses April to yield
10064 <literal>1 mon
1 day
</literal>, while using May would yield
<literal>1 mon
2
10065 days
</literal> because May has
31 days, while April has only
30.
10069 Subtraction of dates and timestamps can also be complex. One conceptually
10070 simple way to perform subtraction is to convert each value to a number
10071 of seconds using
<literal>EXTRACT(EPOCH FROM ...)
</literal>, then subtract the
10072 results; this produces the
10073 number of
<emphasis>seconds
</emphasis> between the two values. This will adjust
10074 for the number of days in each month, timezone changes, and daylight
10075 saving time adjustments. Subtraction of date or timestamp
10076 values with the
<quote><literal>-
</literal></quote> operator
10077 returns the number of days (
24-hours) and hours/minutes/seconds
10078 between the values, making the same adjustments. The
<function>age
</function>
10079 function returns years, months, days, and hours/minutes/seconds,
10080 performing field-by-field subtraction and then adjusting for negative
10081 field values. The following queries illustrate the differences in these
10082 approaches. The sample results were produced with
<literal>timezone
10083 = 'US/Eastern'
</literal>; there is a daylight saving time change between the
10088 SELECT EXTRACT(EPOCH FROM timestamptz '
2013-
07-
01 12:
00:
00') -
10089 EXTRACT(EPOCH FROM timestamptz '
2013-
03-
01 12:
00:
00');
10090 <lineannotation>Result:
</lineannotation><computeroutput>10537200.000000</computeroutput>
10091 SELECT (EXTRACT(EPOCH FROM timestamptz '
2013-
07-
01 12:
00:
00') -
10092 EXTRACT(EPOCH FROM timestamptz '
2013-
03-
01 12:
00:
00'))
10094 <lineannotation>Result:
</lineannotation><computeroutput>121.9583333333333333</computeroutput>
10095 SELECT timestamptz '
2013-
07-
01 12:
00:
00' - timestamptz '
2013-
03-
01 12:
00:
00';
10096 <lineannotation>Result:
</lineannotation><computeroutput>121 days
23:
00:
00</computeroutput>
10097 SELECT age(timestamptz '
2013-
07-
01 12:
00:
00', timestamptz '
2013-
03-
01 12:
00:
00');
10098 <lineannotation>Result:
</lineannotation><computeroutput>4 mons
</computeroutput>
10101 <sect2 id=
"functions-datetime-extract">
10102 <title><function>EXTRACT
</function>,
<function>date_part
</function></title>
10105 <primary>date_part
</primary>
10108 <primary>extract
</primary>
10112 EXTRACT(
<replaceable>field
</replaceable> FROM
<replaceable>source
</replaceable>)
10116 The
<function>extract
</function> function retrieves subfields
10117 such as year or hour from date/time values.
10118 <replaceable>source
</replaceable> must be a value expression of
10119 type
<type>timestamp
</type>,
<type>date
</type>,
<type>time
</type>,
10120 or
<type>interval
</type>. (Timestamps and times can be with or
10121 without time zone.)
10122 <replaceable>field
</replaceable> is an identifier or
10123 string that selects what field to extract from the source value.
10124 Not all fields are valid for every input data type; for example, fields
10125 smaller than a day cannot be extracted from a
<type>date
</type>, while
10126 fields of a day or more cannot be extracted from a
<type>time
</type>.
10127 The
<function>extract
</function> function returns values of type
10128 <type>numeric
</type>.
10132 The following are valid field names:
10134 <!-- alphabetical -->
10137 <term><literal>century
</literal></term>
10140 The century; for
<type>interval
</type> values, the year field
10145 SELECT EXTRACT(CENTURY FROM TIMESTAMP '
2000-
12-
16 12:
21:
13');
10146 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10147 SELECT EXTRACT(CENTURY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10148 <lineannotation>Result:
</lineannotation><computeroutput>21</computeroutput>
10149 SELECT EXTRACT(CENTURY FROM DATE '
0001-
01-
01 AD');
10150 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10151 SELECT EXTRACT(CENTURY FROM DATE '
0001-
12-
31 BC');
10152 <lineannotation>Result:
</lineannotation><computeroutput>-
1</computeroutput>
10153 SELECT EXTRACT(CENTURY FROM INTERVAL '
2001 years');
10154 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10160 <term><literal>day
</literal></term>
10163 The day of the month (
1–31); for
<type>interval
</type>
10164 values, the number of days
10168 SELECT EXTRACT(DAY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10169 <lineannotation>Result:
</lineannotation><computeroutput>16</computeroutput>
10170 SELECT EXTRACT(DAY FROM INTERVAL '
40 days
1 minute');
10171 <lineannotation>Result:
</lineannotation><computeroutput>40</computeroutput>
10178 <term><literal>decade
</literal></term>
10181 The year field divided by
10
10185 SELECT EXTRACT(DECADE FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10186 <lineannotation>Result:
</lineannotation><computeroutput>200</computeroutput>
10192 <term><literal>dow
</literal></term>
10195 The day of the week as Sunday (
<literal>0</literal>) to
10196 Saturday (
<literal>6</literal>)
10200 SELECT EXTRACT(DOW FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10201 <lineannotation>Result:
</lineannotation><computeroutput>5</computeroutput>
10204 Note that
<function>extract
</function>'s day of the week numbering
10205 differs from that of the
<function>to_char(...,
10206 'D')
</function> function.
10213 <term><literal>doy
</literal></term>
10216 The day of the year (
1–365/
366)
10220 SELECT EXTRACT(DOY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10221 <lineannotation>Result:
</lineannotation><computeroutput>47</computeroutput>
10227 <term><literal>epoch
</literal></term>
10230 For
<type>timestamp with time zone
</type> values, the
10231 number of seconds since
1970-
01-
01 00:
00:
00 UTC (negative for
10232 timestamps before that);
10233 for
<type>date
</type> and
<type>timestamp
</type> values, the
10234 nominal number of seconds since
1970-
01-
01 00:
00:
00,
10235 without regard to timezone or daylight-savings rules;
10236 for
<type>interval
</type> values, the total number
10237 of seconds in the interval
10241 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40.12-
08');
10242 <lineannotation>Result:
</lineannotation><computeroutput>982384720.120000</computeroutput>
10243 SELECT EXTRACT(EPOCH FROM TIMESTAMP '
2001-
02-
16 20:
38:
40.12');
10244 <lineannotation>Result:
</lineannotation><computeroutput>982355920.120000</computeroutput>
10245 SELECT EXTRACT(EPOCH FROM INTERVAL '
5 days
3 hours');
10246 <lineannotation>Result:
</lineannotation><computeroutput>442800.000000</computeroutput>
10250 You can convert an epoch value back to a
<type>timestamp with time zone
</type>
10251 with
<function>to_timestamp
</function>:
10254 SELECT to_timestamp(
982384720.12);
10255 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
17 04:
38:
40.12+
00</computeroutput>
10259 Beware that applying
<function>to_timestamp
</function> to an epoch
10260 extracted from a
<type>date
</type> or
<type>timestamp
</type> value
10261 could produce a misleading result: the result will effectively
10262 assume that the original value had been given in UTC, which might
10269 <term><literal>hour
</literal></term>
10272 The hour field (
0–23 in timestamps, unrestricted in
10277 SELECT EXTRACT(HOUR FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10278 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10284 <term><literal>isodow
</literal></term>
10287 The day of the week as Monday (
<literal>1</literal>) to
10288 Sunday (
<literal>7</literal>)
10292 SELECT EXTRACT(ISODOW FROM TIMESTAMP '
2001-
02-
18 20:
38:
40');
10293 <lineannotation>Result:
</lineannotation><computeroutput>7</computeroutput>
10296 This is identical to
<literal>dow
</literal> except for Sunday. This
10297 matches the
<acronym>ISO
</acronym> 8601 day of the week numbering.
10304 <term><literal>isoyear
</literal></term>
10307 The
<acronym>ISO
</acronym> 8601 week-numbering year that the date
10312 SELECT EXTRACT(ISOYEAR FROM DATE '
2006-
01-
01');
10313 <lineannotation>Result:
</lineannotation><computeroutput>2005</computeroutput>
10314 SELECT EXTRACT(ISOYEAR FROM DATE '
2006-
01-
02');
10315 <lineannotation>Result:
</lineannotation><computeroutput>2006</computeroutput>
10319 Each
<acronym>ISO
</acronym> 8601 week-numbering year begins with the
10320 Monday of the week containing the
4th of January, so in early
10321 January or late December the
<acronym>ISO
</acronym> year may be
10322 different from the Gregorian year. See the
<literal>week
</literal>
10323 field for more information.
10329 <term><literal>julian
</literal></term>
10332 The
<firstterm>Julian Date
</firstterm> corresponding to the
10333 date or timestamp. Timestamps
10334 that are not local midnight result in a fractional value. See
10335 <xref linkend=
"datetime-julian-dates"/> for more information.
10339 SELECT EXTRACT(JULIAN FROM DATE '
2006-
01-
01');
10340 <lineannotation>Result:
</lineannotation><computeroutput>2453737</computeroutput>
10341 SELECT EXTRACT(JULIAN FROM TIMESTAMP '
2006-
01-
01 12:
00');
10342 <lineannotation>Result:
</lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
10348 <term><literal>microseconds
</literal></term>
10351 The seconds field, including fractional parts, multiplied by
1
10352 000 000; note that this includes full seconds
10356 SELECT EXTRACT(MICROSECONDS FROM TIME '
17:
12:
28.5');
10357 <lineannotation>Result:
</lineannotation><computeroutput>28500000</computeroutput>
10363 <term><literal>millennium
</literal></term>
10366 The millennium; for
<type>interval
</type> values, the year field
10371 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10372 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10373 SELECT EXTRACT(MILLENNIUM FROM INTERVAL '
2001 years');
10374 <lineannotation>Result:
</lineannotation><computeroutput>2</computeroutput>
10378 Years in the
1900s are in the second millennium.
10379 The third millennium started January
1,
2001.
10385 <term><literal>milliseconds
</literal></term>
10388 The seconds field, including fractional parts, multiplied by
10389 1000. Note that this includes full seconds.
10393 SELECT EXTRACT(MILLISECONDS FROM TIME '
17:
12:
28.5');
10394 <lineannotation>Result:
</lineannotation><computeroutput>28500.000</computeroutput>
10400 <term><literal>minute
</literal></term>
10403 The minutes field (
0–59)
10407 SELECT EXTRACT(MINUTE FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10408 <lineannotation>Result:
</lineannotation><computeroutput>38</computeroutput>
10414 <term><literal>month
</literal></term>
10417 The number of the month within the year (
1–12);
10418 for
<type>interval
</type> values, the number of months modulo
12
10423 SELECT EXTRACT(MONTH FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10424 <lineannotation>Result:
</lineannotation><computeroutput>2</computeroutput>
10425 SELECT EXTRACT(MONTH FROM INTERVAL '
2 years
3 months');
10426 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10427 SELECT EXTRACT(MONTH FROM INTERVAL '
2 years
13 months');
10428 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10434 <term><literal>quarter
</literal></term>
10437 The quarter of the year (
1–4) that the date is in;
10438 for
<type>interval
</type> values, the month field divided by
3
10443 SELECT EXTRACT(QUARTER FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10444 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10445 SELECT EXTRACT(QUARTER FROM INTERVAL '
1 year
6 months');
10446 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10452 <term><literal>second
</literal></term>
10455 The seconds field, including any fractional seconds
10459 SELECT EXTRACT(SECOND FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10460 <lineannotation>Result:
</lineannotation><computeroutput>40.000000</computeroutput>
10461 SELECT EXTRACT(SECOND FROM TIME '
17:
12:
28.5');
10462 <lineannotation>Result:
</lineannotation><computeroutput>28.500000</computeroutput>
10467 <term><literal>timezone
</literal></term>
10470 The time zone offset from UTC, measured in seconds. Positive values
10471 correspond to time zones east of UTC, negative values to
10472 zones west of UTC. (Technically,
10473 <productname>PostgreSQL
</productname> does not use UTC because
10474 leap seconds are not handled.)
10480 <term><literal>timezone_hour
</literal></term>
10483 The hour component of the time zone offset
10489 <term><literal>timezone_minute
</literal></term>
10492 The minute component of the time zone offset
10498 <term><literal>week
</literal></term>
10501 The number of the
<acronym>ISO
</acronym> 8601 week-numbering week of
10502 the year. By definition, ISO weeks start on Mondays and the first
10503 week of a year contains January
4 of that year. In other words, the
10504 first Thursday of a year is in week
1 of that year.
10507 In the ISO week-numbering system, it is possible for early-January
10508 dates to be part of the
52nd or
53rd week of the previous year, and for
10509 late-December dates to be part of the first week of the next year.
10510 For example,
<literal>2005-
01-
01</literal> is part of the
53rd week of year
10511 2004, and
<literal>2006-
01-
01</literal> is part of the
52nd week of year
10512 2005, while
<literal>2012-
12-
31</literal> is part of the first week of
2013.
10513 It's recommended to use the
<literal>isoyear
</literal> field together with
10514 <literal>week
</literal> to get consistent results.
10518 For
<type>interval
</type> values, the week field is simply the number
10519 of integral days divided by
7.
10523 SELECT EXTRACT(WEEK FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10524 <lineannotation>Result:
</lineannotation><computeroutput>7</computeroutput>
10525 SELECT EXTRACT(WEEK FROM INTERVAL '
13 days
24 hours');
10526 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10532 <term><literal>year
</literal></term>
10535 The year field. Keep in mind there is no
<literal>0 AD
</literal>, so subtracting
10536 <literal>BC
</literal> years from
<literal>AD
</literal> years should be done with care.
10540 SELECT EXTRACT(YEAR FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10541 <lineannotation>Result:
</lineannotation><computeroutput>2001</computeroutput>
10550 When processing an
<type>interval
</type> value,
10551 the
<function>extract
</function> function produces field values that
10552 match the interpretation used by the interval output function. This
10553 can produce surprising results if one starts with a non-normalized
10554 interval representation, for example:
10556 SELECT INTERVAL '
80 minutes';
10557 <lineannotation>Result:
</lineannotation><computeroutput>01:
20:
00</computeroutput>
10558 SELECT EXTRACT(MINUTES FROM INTERVAL '
80 minutes');
10559 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10565 When the input value is +/-Infinity,
<function>extract
</function> returns
10566 +/-Infinity for monotonically-increasing fields (
<literal>epoch
</literal>,
10567 <literal>julian
</literal>,
<literal>year
</literal>,
<literal>isoyear
</literal>,
10568 <literal>decade
</literal>,
<literal>century
</literal>, and
<literal>millennium
</literal>
10569 for
<type>timestamp
</type> inputs;
<literal>epoch
</literal>,
<literal>hour
</literal>,
10570 <literal>day
</literal>,
<literal>year
</literal>,
<literal>decade
</literal>,
10571 <literal>century
</literal>, and
<literal>millennium
</literal> for
10572 <type>interval
</type> inputs).
10573 For other fields, NULL is returned.
<productname>PostgreSQL
</productname>
10574 versions before
9.6 returned zero for all cases of infinite input.
10579 The
<function>extract
</function> function is primarily intended
10580 for computational processing. For formatting date/time values for
10581 display, see
<xref linkend=
"functions-formatting"/>.
10585 The
<function>date_part
</function> function is modeled on the traditional
10586 <productname>Ingres
</productname> equivalent to the
10587 <acronym>SQL
</acronym>-standard function
<function>extract
</function>:
10589 date_part('
<replaceable>field
</replaceable>',
<replaceable>source
</replaceable>)
10591 Note that here the
<replaceable>field
</replaceable> parameter needs to
10592 be a string value, not a name. The valid field names for
10593 <function>date_part
</function> are the same as for
10594 <function>extract
</function>.
10595 For historical reasons, the
<function>date_part
</function> function
10596 returns values of type
<type>double precision
</type>. This can result in
10597 a loss of precision in certain uses. Using
<function>extract
</function>
10598 is recommended instead.
10602 SELECT date_part('day', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10603 <lineannotation>Result:
</lineannotation><computeroutput>16</computeroutput>
10604 SELECT date_part('hour', INTERVAL '
4 hours
3 minutes');
10605 <lineannotation>Result:
</lineannotation><computeroutput>4</computeroutput>
10610 <sect2 id=
"functions-datetime-trunc">
10611 <title><function>date_trunc
</function></title>
10614 <primary>date_trunc
</primary>
10618 The function
<function>date_trunc
</function> is conceptually
10619 similar to the
<function>trunc
</function> function for numbers.
10624 date_trunc(
<replaceable>field
</replaceable>,
<replaceable>source
</replaceable> <optional>,
<replaceable>time_zone
</replaceable> </optional>)
10626 <replaceable>source
</replaceable> is a value expression of type
10627 <type>timestamp
</type>,
<type>timestamp with time zone
</type>,
10628 or
<type>interval
</type>.
10629 (Values of type
<type>date
</type> and
10630 <type>time
</type> are cast automatically to
<type>timestamp
</type> or
10631 <type>interval
</type>, respectively.)
10632 <replaceable>field
</replaceable> selects to which precision to
10633 truncate the input value. The return value is likewise of type
10634 <type>timestamp
</type>,
<type>timestamp with time zone
</type>,
10635 or
<type>interval
</type>,
10636 and it has all fields that are less significant than the
10637 selected one set to zero (or one, for day and month).
10641 Valid values for
<replaceable>field
</replaceable> are:
10643 <member><literal>microseconds
</literal></member>
10644 <member><literal>milliseconds
</literal></member>
10645 <member><literal>second
</literal></member>
10646 <member><literal>minute
</literal></member>
10647 <member><literal>hour
</literal></member>
10648 <member><literal>day
</literal></member>
10649 <member><literal>week
</literal></member>
10650 <member><literal>month
</literal></member>
10651 <member><literal>quarter
</literal></member>
10652 <member><literal>year
</literal></member>
10653 <member><literal>decade
</literal></member>
10654 <member><literal>century
</literal></member>
10655 <member><literal>millennium
</literal></member>
10660 When the input value is of type
<type>timestamp with time zone
</type>,
10661 the truncation is performed with respect to a particular time zone;
10662 for example, truncation to
<literal>day
</literal> produces a value that
10663 is midnight in that zone. By default, truncation is done with respect
10664 to the current
<xref linkend=
"guc-timezone"/> setting, but the
10665 optional
<replaceable>time_zone
</replaceable> argument can be provided
10666 to specify a different time zone. The time zone name can be specified
10667 in any of the ways described in
<xref linkend=
"datatype-timezones"/>.
10671 A time zone cannot be specified when processing
<type>timestamp without
10672 time zone
</type> or
<type>interval
</type> inputs. These are always
10673 taken at face value.
10677 Examples (assuming the local time zone is
<literal>America/New_York
</literal>):
10679 SELECT date_trunc('hour', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10680 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 20:
00:
00</computeroutput>
10681 SELECT date_trunc('year', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10682 <lineannotation>Result:
</lineannotation><computeroutput>2001-
01-
01 00:
00:
00</computeroutput>
10683 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40+
00');
10684 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 00:
00:
00-
05</computeroutput>
10685 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40+
00', 'Australia/Sydney');
10686 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 08:
00:
00-
05</computeroutput>
10687 SELECT date_trunc('hour', INTERVAL '
3 days
02:
47:
33');
10688 <lineannotation>Result:
</lineannotation><computeroutput>3 days
02:
00:
00</computeroutput>
10693 <sect2 id=
"functions-datetime-bin">
10694 <title><function>date_bin
</function></title>
10697 <primary>date_bin
</primary>
10701 The function
<function>date_bin
</function> <quote>bins
</quote> the input
10702 timestamp into the specified interval (the
<firstterm>stride
</firstterm>)
10703 aligned with a specified origin.
10708 date_bin(
<replaceable>stride
</replaceable>,
<replaceable>source
</replaceable>,
<replaceable>origin
</replaceable>)
10710 <replaceable>source
</replaceable> is a value expression of type
10711 <type>timestamp
</type> or
<type>timestamp with time zone
</type>. (Values
10712 of type
<type>date
</type> are cast automatically to
10713 <type>timestamp
</type>.)
<replaceable>stride
</replaceable> is a value
10714 expression of type
<type>interval
</type>. The return value is likewise
10715 of type
<type>timestamp
</type> or
<type>timestamp with time zone
</type>,
10716 and it marks the beginning of the bin into which the
10717 <replaceable>source
</replaceable> is placed.
10723 SELECT date_bin('
15 minutes', TIMESTAMP '
2020-
02-
11 15:
44:
17', TIMESTAMP '
2001-
01-
01');
10724 <lineannotation>Result:
</lineannotation><computeroutput>2020-
02-
11 15:
30:
00</computeroutput>
10725 SELECT date_bin('
15 minutes', TIMESTAMP '
2020-
02-
11 15:
44:
17', TIMESTAMP '
2001-
01-
01 00:
02:
30');
10726 <lineannotation>Result:
</lineannotation><computeroutput>2020-
02-
11 15:
32:
30</computeroutput>
10731 In the case of full units (
1 minute,
1 hour, etc.), it gives the same result as
10732 the analogous
<function>date_trunc
</function> call, but the difference is
10733 that
<function>date_bin
</function> can truncate to an arbitrary interval.
10737 The
<parameter>stride
</parameter> interval must be greater than zero and
10738 cannot contain units of month or larger.
10742 <sect2 id=
"functions-datetime-zoneconvert">
10743 <title><literal>AT TIME ZONE and AT LOCAL
</literal></title>
10746 <primary>time zone
</primary>
10747 <secondary>conversion
</secondary>
10751 <primary>AT TIME ZONE
</primary>
10755 <primary>AT LOCAL
</primary>
10759 The
<literal>AT TIME ZONE
</literal> operator converts time
10760 stamp
<emphasis>without
</emphasis> time zone to/from
10761 time stamp
<emphasis>with
</emphasis> time zone, and
10762 <type>time with time zone
</type> values to different time
10763 zones.
<xref linkend=
"functions-datetime-zoneconvert-table"/> shows its
10767 <table id=
"functions-datetime-zoneconvert-table">
10768 <title><literal>AT TIME ZONE
</literal> and
<literal>AT LOCAL
</literal> Variants
</title>
10772 <entry role=
"func_table_entry"><para role=
"func_signature">
10786 <entry role=
"func_table_entry"><para role=
"func_signature">
10787 <type>timestamp without time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10788 <returnvalue>timestamp with time zone
</returnvalue>
10791 Converts given time stamp
<emphasis>without
</emphasis> time zone to
10792 time stamp
<emphasis>with
</emphasis> time zone, assuming the given
10793 value is in the named time zone.
10796 <literal>timestamp '
2001-
02-
16 20:
38:
40' at time zone 'America/Denver'
</literal>
10797 <returnvalue>2001-
02-
17 03:
38:
40+
00</returnvalue>
10802 <entry role=
"func_table_entry"><para role=
"func_signature">
10803 <type>timestamp without time zone
</type> <literal>AT LOCAL
</literal>
10804 <returnvalue>timestamp with time zone
</returnvalue>
10807 Converts given time stamp
<emphasis>without
</emphasis> time zone to
10808 time stamp
<emphasis>with
</emphasis> the session's
10809 <varname>TimeZone
</varname> value as time zone.
10812 <literal>timestamp '
2001-
02-
16 20:
38:
40' at local
</literal>
10813 <returnvalue>2001-
02-
17 03:
38:
40+
00</returnvalue>
10818 <entry role=
"func_table_entry"><para role=
"func_signature">
10819 <type>timestamp with time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10820 <returnvalue>timestamp without time zone
</returnvalue>
10823 Converts given time stamp
<emphasis>with
</emphasis> time zone to
10824 time stamp
<emphasis>without
</emphasis> time zone, as the time would
10825 appear in that zone.
10828 <literal>timestamp with time zone '
2001-
02-
16 20:
38:
40-
05' at time zone 'America/Denver'
</literal>
10829 <returnvalue>2001-
02-
16 18:
38:
40</returnvalue>
10834 <entry role=
"func_table_entry"><para role=
"func_signature">
10835 <type>timestamp with time zone
</type> <literal>AT LOCAL
</literal>
10836 <returnvalue>timestamp without time zone
</returnvalue>
10839 Converts given time stamp
<emphasis>with
</emphasis> time zone to
10840 time stamp
<emphasis>without
</emphasis> time zone, as the time would
10841 appear with the session's
<varname>TimeZone
</varname> value as time zone.
10844 <literal>timestamp with time zone '
2001-
02-
16 20:
38:
40-
05' at local
</literal>
10845 <returnvalue>2001-
02-
16 18:
38:
40</returnvalue>
10850 <entry role=
"func_table_entry"><para role=
"func_signature">
10851 <type>time with time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10852 <returnvalue>time with time zone
</returnvalue>
10855 Converts given time
<emphasis>with
</emphasis> time zone to a new time
10856 zone. Since no date is supplied, this uses the currently active UTC
10857 offset for the named destination zone.
10860 <literal>time with time zone '
05:
34:
17-
05' at time zone 'UTC'
</literal>
10861 <returnvalue>10:
34:
17+
00</returnvalue>
10866 <entry role=
"func_table_entry"><para role=
"func_signature">
10867 <type>time with time zone
</type> <literal>AT LOCAL
</literal>
10868 <returnvalue>time with time zone
</returnvalue>
10871 Converts given time
<emphasis>with
</emphasis> time zone to a new time
10872 zone. Since no date is supplied, this uses the currently active UTC
10873 offset for the session's
<varname>TimeZone
</varname> value.
10876 Assuming the session's
<varname>TimeZone
</varname> is set to
<literal>UTC
</literal>:
10879 <literal>time with time zone '
05:
34:
17-
05' at local
</literal>
10880 <returnvalue>10:
34:
17+
00</returnvalue>
10888 In these expressions, the desired time zone
<replaceable>zone
</replaceable> can be
10889 specified either as a text value (e.g.,
<literal>'America/Los_Angeles'
</literal>)
10890 or as an interval (e.g.,
<literal>INTERVAL '-
08:
00'
</literal>).
10891 In the text case, a time zone name can be specified in any of the ways
10892 described in
<xref linkend=
"datatype-timezones"/>.
10893 The interval case is only useful for zones that have fixed offsets from
10894 UTC, so it is not very common in practice.
10898 The syntax
<literal>AT LOCAL
</literal> may be used as shorthand for
10899 <literal>AT TIME ZONE
<replaceable>local
</replaceable></literal>, where
10900 <replaceable>local
</replaceable> is the session's
10901 <varname>TimeZone
</varname> value.
10905 Examples (assuming the current
<xref linkend=
"guc-timezone"/> setting
10906 is
<literal>America/Los_Angeles
</literal>):
10908 SELECT TIMESTAMP '
2001-
02-
16 20:
38:
40' AT TIME ZONE 'America/Denver';
10909 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 19:
38:
40-
08</computeroutput>
10910 SELECT TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40-
05' AT TIME ZONE 'America/Denver';
10911 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 18:
38:
40</computeroutput>
10912 SELECT TIMESTAMP '
2001-
02-
16 20:
38:
40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
10913 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 05:
38:
40</computeroutput>
10914 SELECT TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40-
05' AT LOCAL;
10915 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 17:
38:
40</computeroutput>
10916 SELECT TIME WITH TIME ZONE '
20:
38:
40-
05' AT LOCAL;
10917 <lineannotation>Result:
</lineannotation><computeroutput>17:
38:
40</computeroutput>
10919 The first example adds a time zone to a value that lacks it, and
10920 displays the value using the current
<varname>TimeZone
</varname>
10921 setting. The second example shifts the time stamp with time zone value
10922 to the specified time zone, and returns the value without a time zone.
10923 This allows storage and display of values different from the current
10924 <varname>TimeZone
</varname> setting. The third example converts
10925 Tokyo time to Chicago time. The fourth example shifts the time stamp
10926 with time zone value to the time zone currently specified by the
10927 <varname>TimeZone
</varname> setting and returns the value without a
10932 The fifth example is a cautionary tale. Due to the fact that there is no
10933 date associated with the input value, the conversion is made using the
10934 current date of the session. Therefore, this static example may show a wrong
10935 result depending on the time of the year it is viewed because
10936 <literal>'America/Los_Angeles'
</literal> observes Daylight Savings Time.
10940 The function
<literal><function>timezone
</function>(
<replaceable>zone
</replaceable>,
10941 <replaceable>timestamp
</replaceable>)
</literal> is equivalent to the SQL-conforming construct
10942 <literal><replaceable>timestamp
</replaceable> AT TIME ZONE
10943 <replaceable>zone
</replaceable></literal>.
10947 The function
<literal><function>timezone
</function>(
<replaceable>zone
</replaceable>,
10948 <replaceable>time
</replaceable>)
</literal> is equivalent to the SQL-conforming construct
10949 <literal><replaceable>time
</replaceable> AT TIME ZONE
10950 <replaceable>zone
</replaceable></literal>.
10954 The function
<literal><function>timezone
</function>(
<replaceable>timestamp
</replaceable>)
</literal>
10955 is equivalent to the SQL-conforming construct
<literal><replaceable>timestamp
</replaceable>
10956 AT LOCAL
</literal>.
10960 The function
<literal><function>timezone
</function>(
<replaceable>time
</replaceable>)
</literal>
10961 is equivalent to the SQL-conforming construct
<literal><replaceable>time
</replaceable>
10962 AT LOCAL
</literal>.
10966 <sect2 id=
"functions-datetime-current">
10967 <title>Current Date/Time
</title>
10970 <primary>date
</primary>
10971 <secondary>current
</secondary>
10975 <primary>time
</primary>
10976 <secondary>current
</secondary>
10980 <productname>PostgreSQL
</productname> provides a number of functions
10981 that return values related to the current date and time. These
10982 SQL-standard functions all return values based on the start time of
10983 the current transaction:
10988 CURRENT_TIME(
<replaceable>precision
</replaceable>)
10989 CURRENT_TIMESTAMP(
<replaceable>precision
</replaceable>)
10992 LOCALTIME(
<replaceable>precision
</replaceable>)
10993 LOCALTIMESTAMP(
<replaceable>precision
</replaceable>)
10998 <function>CURRENT_TIME
</function> and
10999 <function>CURRENT_TIMESTAMP
</function> deliver values with time zone;
11000 <function>LOCALTIME
</function> and
11001 <function>LOCALTIMESTAMP
</function> deliver values without time zone.
11005 <function>CURRENT_TIME
</function>,
11006 <function>CURRENT_TIMESTAMP
</function>,
11007 <function>LOCALTIME
</function>, and
11008 <function>LOCALTIMESTAMP
</function>
11009 can optionally take
11010 a precision parameter, which causes the result to be rounded
11011 to that many fractional digits in the seconds field. Without a precision parameter,
11012 the result is given to the full available precision.
11018 SELECT CURRENT_TIME;
11019 <lineannotation>Result:
</lineannotation><computeroutput>14:
39:
53.662522-
05</computeroutput>
11020 SELECT CURRENT_DATE;
11021 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23</computeroutput>
11022 SELECT CURRENT_TIMESTAMP;
11023 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.662522-
05</computeroutput>
11024 SELECT CURRENT_TIMESTAMP(
2);
11025 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.66-
05</computeroutput>
11026 SELECT LOCALTIMESTAMP;
11027 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.662522</computeroutput>
11032 Since these functions return
11033 the start time of the current transaction, their values do not
11034 change during the transaction. This is considered a feature:
11035 the intent is to allow a single transaction to have a consistent
11036 notion of the
<quote>current
</quote> time, so that multiple
11037 modifications within the same transaction bear the same
11043 Other database systems might advance these values more
11049 <productname>PostgreSQL
</productname> also provides functions that
11050 return the start time of the current statement, as well as the actual
11051 current time at the instant the function is called. The complete list
11052 of non-SQL-standard time functions is:
11054 transaction_timestamp()
11055 statement_timestamp()
11063 <function>transaction_timestamp()
</function> is equivalent to
11064 <function>CURRENT_TIMESTAMP
</function>, but is named to clearly reflect
11066 <function>statement_timestamp()
</function> returns the start time of the current
11067 statement (more specifically, the time of receipt of the latest command
11068 message from the client).
11069 <function>statement_timestamp()
</function> and
<function>transaction_timestamp()
</function>
11070 return the same value during the first command of a transaction, but might
11071 differ during subsequent commands.
11072 <function>clock_timestamp()
</function> returns the actual current time, and
11073 therefore its value changes even within a single SQL command.
11074 <function>timeofday()
</function> is a historical
11075 <productname>PostgreSQL
</productname> function. Like
11076 <function>clock_timestamp()
</function>, it returns the actual current time,
11077 but as a formatted
<type>text
</type> string rather than a
<type>timestamp
11078 with time zone
</type> value.
11079 <function>now()
</function> is a traditional
<productname>PostgreSQL
</productname>
11080 equivalent to
<function>transaction_timestamp()
</function>.
11084 All the date/time data types also accept the special literal value
11085 <literal>now
</literal> to specify the current date and time (again,
11086 interpreted as the transaction start time). Thus,
11087 the following three all return the same result:
11089 SELECT CURRENT_TIMESTAMP;
11091 SELECT TIMESTAMP 'now'; -- but see tip below
11097 Do not use the third form when specifying a value to be evaluated later,
11098 for example in a
<literal>DEFAULT
</literal> clause for a table column.
11099 The system will convert
<literal>now
</literal>
11100 to a
<type>timestamp
</type> as soon as the constant is parsed, so that when
11101 the default value is needed,
11102 the time of the table creation would be used! The first two
11103 forms will not be evaluated until the default value is used,
11104 because they are function calls. Thus they will give the desired
11105 behavior of defaulting to the time of row insertion.
11106 (See also
<xref linkend=
"datatype-datetime-special-values"/>.)
11111 <sect2 id=
"functions-datetime-delay">
11112 <title>Delaying Execution
</title>
11115 <primary>pg_sleep
</primary>
11118 <primary>pg_sleep_for
</primary>
11121 <primary>pg_sleep_until
</primary>
11124 <primary>sleep
</primary>
11127 <primary>delay
</primary>
11131 The following functions are available to delay execution of the server
11134 pg_sleep (
<type>double precision
</type> )
11135 pg_sleep_for (
<type>interval
</type> )
11136 pg_sleep_until (
<type>timestamp with time zone
</type> )
11139 <function>pg_sleep
</function> makes the current session's process
11140 sleep until the given number of seconds have
11141 elapsed. Fractional-second delays can be specified.
11142 <function>pg_sleep_for
</function> is a convenience function to
11143 allow the sleep time to be specified as an
<type>interval
</type>.
11144 <function>pg_sleep_until
</function> is a convenience function for when
11145 a specific wake-up time is desired.
11149 SELECT pg_sleep(
1.5);
11150 SELECT pg_sleep_for('
5 minutes');
11151 SELECT pg_sleep_until('tomorrow
03:
00');
11157 The effective resolution of the sleep interval is platform-specific;
11158 0.01 seconds is a common value. The sleep delay will be at least as long
11159 as specified. It might be longer depending on factors such as server load.
11160 In particular,
<function>pg_sleep_until
</function> is not guaranteed to
11161 wake up exactly at the specified time, but it will not wake up any earlier.
11167 Make sure that your session does not hold more locks than necessary
11168 when calling
<function>pg_sleep
</function> or its variants. Otherwise
11169 other sessions might have to wait for your sleeping process, slowing down
11178 <sect1 id=
"functions-enum">
11179 <title>Enum Support Functions
</title>
11182 For enum types (described in
<xref linkend=
"datatype-enum"/>),
11183 there are several functions that allow cleaner programming without
11184 hard-coding particular values of an enum type.
11185 These are listed in
<xref linkend=
"functions-enum-table"/>. The examples
11186 assume an enum type created as:
11189 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
11194 <table id=
"functions-enum-table">
11195 <title>Enum Support Functions
</title>
11199 <entry role=
"func_table_entry"><para role=
"func_signature">
11213 <entry role=
"func_table_entry"><para role=
"func_signature">
11215 <primary>enum_first
</primary>
11217 <function>enum_first
</function> (
<type>anyenum
</type> )
11218 <returnvalue>anyenum
</returnvalue>
11221 Returns the first value of the input enum type.
11224 <literal>enum_first(null::rainbow)
</literal>
11225 <returnvalue>red
</returnvalue>
11229 <entry role=
"func_table_entry"><para role=
"func_signature">
11231 <primary>enum_last
</primary>
11233 <function>enum_last
</function> (
<type>anyenum
</type> )
11234 <returnvalue>anyenum
</returnvalue>
11237 Returns the last value of the input enum type.
11240 <literal>enum_last(null::rainbow)
</literal>
11241 <returnvalue>purple
</returnvalue>
11245 <entry role=
"func_table_entry"><para role=
"func_signature">
11247 <primary>enum_range
</primary>
11249 <function>enum_range
</function> (
<type>anyenum
</type> )
11250 <returnvalue>anyarray
</returnvalue>
11253 Returns all values of the input enum type in an ordered array.
11256 <literal>enum_range(null::rainbow)
</literal>
11257 <returnvalue>{red,orange,yellow,
&zwsp;green,blue,purple}
</returnvalue>
11261 <entry role=
"func_table_entry"><para role=
"func_signature">
11262 <function>enum_range
</function> (
<type>anyenum
</type>,
<type>anyenum
</type> )
11263 <returnvalue>anyarray
</returnvalue>
11266 Returns the range between the two given enum values, as an ordered
11267 array. The values must be from the same enum type. If the first
11268 parameter is null, the result will start with the first value of
11270 If the second parameter is null, the result will end with the last
11271 value of the enum type.
11274 <literal>enum_range('orange'::rainbow, 'green'::rainbow)
</literal>
11275 <returnvalue>{orange,yellow,green}
</returnvalue>
11278 <literal>enum_range(NULL, 'green'::rainbow)
</literal>
11279 <returnvalue>{red,orange,
&zwsp;yellow,green}
</returnvalue>
11282 <literal>enum_range('orange'::rainbow, NULL)
</literal>
11283 <returnvalue>{orange,yellow,green,
&zwsp;blue,purple}
</returnvalue>
11291 Notice that except for the two-argument form of
<function>enum_range
</function>,
11292 these functions disregard the specific value passed to them; they care
11293 only about its declared data type. Either null or a specific value of
11294 the type can be passed, with the same result. It is more common to
11295 apply these functions to a table column or function argument than to
11296 a hardwired type name as used in the examples.
11300 <sect1 id=
"functions-geometry">
11301 <title>Geometric Functions and Operators
</title>
11304 The geometric types
<type>point
</type>,
<type>box
</type>,
11305 <type>lseg
</type>,
<type>line
</type>,
<type>path
</type>,
11306 <type>polygon
</type>, and
<type>circle
</type> have a large set of
11307 native support functions and operators, shown in
<xref
11308 linkend=
"functions-geometry-op-table"/>,
<xref
11309 linkend=
"functions-geometry-func-table"/>, and
<xref
11310 linkend=
"functions-geometry-conv-table"/>.
11313 <table id=
"functions-geometry-op-table">
11314 <title>Geometric Operators
</title>
11318 <entry role=
"func_table_entry"><para role=
"func_signature">
11332 <entry role=
"func_table_entry"><para role=
"func_signature">
11333 <replaceable>geometric_type
</replaceable> <literal>+
</literal> <type>point
</type>
11334 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11337 Adds the coordinates of the second
<type>point
</type> to those of each
11338 point of the first argument, thus performing translation.
11339 Available for
<type>point
</type>,
<type>box
</type>,
<type>path
</type>,
11340 <type>circle
</type>.
11343 <literal>box '(
1,
1),(
0,
0)' + point '(
2,
0)'
</literal>
11344 <returnvalue>(
3,
1),(
2,
0)
</returnvalue>
11349 <entry role=
"func_table_entry"><para role=
"func_signature">
11350 <type>path
</type> <literal>+
</literal> <type>path
</type>
11351 <returnvalue>path
</returnvalue>
11354 Concatenates two open paths (returns NULL if either path is closed).
11357 <literal>path '[(
0,
0),(
1,
1)]' + path '[(
2,
2),(
3,
3),(
4,
4)]'
</literal>
11358 <returnvalue>[(
0,
0),(
1,
1),(
2,
2),(
3,
3),(
4,
4)]
</returnvalue>
11363 <entry role=
"func_table_entry"><para role=
"func_signature">
11364 <replaceable>geometric_type
</replaceable> <literal>-
</literal> <type>point
</type>
11365 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11368 Subtracts the coordinates of the second
<type>point
</type> from those
11369 of each point of the first argument, thus performing translation.
11370 Available for
<type>point
</type>,
<type>box
</type>,
<type>path
</type>,
11371 <type>circle
</type>.
11374 <literal>box '(
1,
1),(
0,
0)' - point '(
2,
0)'
</literal>
11375 <returnvalue>(-
1,
1),(-
2,
0)
</returnvalue>
11380 <entry role=
"func_table_entry"><para role=
"func_signature">
11381 <replaceable>geometric_type
</replaceable> <literal>*
</literal> <type>point
</type>
11382 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11385 Multiplies each point of the first argument by the second
11386 <type>point
</type> (treating a point as being a complex number
11387 represented by real and imaginary parts, and performing standard
11388 complex multiplication). If one interprets
11389 the second
<type>point
</type> as a vector, this is equivalent to
11390 scaling the object's size and distance from the origin by the length
11391 of the vector, and rotating it counterclockwise around the origin by
11392 the vector's angle from the
<replaceable>x
</replaceable> axis.
11393 Available for
<type>point
</type>,
<type>box
</type>,
<footnote
11394 id=
"functions-geometry-rotation-fn"><para><quote>Rotating
</quote> a
11395 box with these operators only moves its corner points: the box is
11396 still considered to have sides parallel to the axes. Hence the box's
11397 size is not preserved, as a true rotation would do.
</para></footnote>
11398 <type>path
</type>,
<type>circle
</type>.
11401 <literal>path '((
0,
0),(
1,
0),(
1,
1))' * point '(
3.0,
0)'
</literal>
11402 <returnvalue>((
0,
0),(
3,
0),(
3,
3))
</returnvalue>
11405 <literal>path '((
0,
0),(
1,
0),(
1,
1))' * point(cosd(
45), sind(
45))
</literal>
11406 <returnvalue>((
0,
0),
&zwsp;(
0.7071067811865475,
0.7071067811865475),
&zwsp;(
0,
1.414213562373095))
</returnvalue>
11411 <entry role=
"func_table_entry"><para role=
"func_signature">
11412 <replaceable>geometric_type
</replaceable> <literal>/
</literal> <type>point
</type>
11413 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11416 Divides each point of the first argument by the second
11417 <type>point
</type> (treating a point as being a complex number
11418 represented by real and imaginary parts, and performing standard
11419 complex division). If one interprets
11420 the second
<type>point
</type> as a vector, this is equivalent to
11421 scaling the object's size and distance from the origin down by the
11422 length of the vector, and rotating it clockwise around the origin by
11423 the vector's angle from the
<replaceable>x
</replaceable> axis.
11424 Available for
<type>point
</type>,
<type>box
</type>,
<footnoteref
11425 linkend=
"functions-geometry-rotation-fn"/> <type>path
</type>,
11426 <type>circle
</type>.
11429 <literal>path '((
0,
0),(
1,
0),(
1,
1))' / point '(
2.0,
0)'
</literal>
11430 <returnvalue>((
0,
0),(
0.5,
0),(
0.5,
0.5))
</returnvalue>
11433 <literal>path '((
0,
0),(
1,
0),(
1,
1))' / point(cosd(
45), sind(
45))
</literal>
11434 <returnvalue>((
0,
0),
&zwsp;(
0.7071067811865476,-
0.7071067811865476),
&zwsp;(
1.4142135623730951,
0))
</returnvalue>
11439 <entry role=
"func_table_entry"><para role=
"func_signature">
11440 <literal>@-@
</literal> <replaceable>geometric_type
</replaceable>
11441 <returnvalue>double precision
</returnvalue>
11444 Computes the total length.
11445 Available for
<type>lseg
</type>,
<type>path
</type>.
11448 <literal>@-@ path '[(
0,
0),(
1,
0),(
1,
1)]'
</literal>
11449 <returnvalue>2</returnvalue>
11454 <entry role=
"func_table_entry"><para role=
"func_signature">
11455 <literal>@@
</literal> <replaceable>geometric_type
</replaceable>
11456 <returnvalue>point
</returnvalue>
11459 Computes the center point.
11460 Available for
<type>box
</type>,
<type>lseg
</type>,
11461 <type>polygon
</type>,
<type>circle
</type>.
11464 <literal>@@ box '(
2,
2),(
0,
0)'
</literal>
11465 <returnvalue>(
1,
1)
</returnvalue>
11470 <entry role=
"func_table_entry"><para role=
"func_signature">
11471 <literal>#
</literal> <replaceable>geometric_type
</replaceable>
11472 <returnvalue>integer
</returnvalue>
11475 Returns the number of points.
11476 Available for
<type>path
</type>,
<type>polygon
</type>.
11479 <literal># path '((
1,
0),(
0,
1),(-
1,
0))'
</literal>
11480 <returnvalue>3</returnvalue>
11485 <entry role=
"func_table_entry"><para role=
"func_signature">
11486 <replaceable>geometric_type
</replaceable> <literal>#
</literal> <replaceable>geometric_type
</replaceable>
11487 <returnvalue>point
</returnvalue>
11490 Computes the point of intersection, or NULL if there is none.
11491 Available for
<type>lseg
</type>,
<type>line
</type>.
11494 <literal>lseg '[(
0,
0),(
1,
1)]' # lseg '[(
1,
0),(
0,
1)]'
</literal>
11495 <returnvalue>(
0.5,
0.5)
</returnvalue>
11500 <entry role=
"func_table_entry"><para role=
"func_signature">
11501 <type>box
</type> <literal>#
</literal> <type>box
</type>
11502 <returnvalue>box
</returnvalue>
11505 Computes the intersection of two boxes, or NULL if there is none.
11508 <literal>box '(
2,
2),(-
1,-
1)' # box '(
1,
1),(-
2,-
2)'
</literal>
11509 <returnvalue>(
1,
1),(-
1,-
1)
</returnvalue>
11514 <entry role=
"func_table_entry"><para role=
"func_signature">
11515 <replaceable>geometric_type
</replaceable> <literal>##
</literal> <replaceable>geometric_type
</replaceable>
11516 <returnvalue>point
</returnvalue>
11519 Computes the closest point to the first object on the second object.
11520 Available for these pairs of types:
11521 (
<type>point
</type>,
<type>box
</type>),
11522 (
<type>point
</type>,
<type>lseg
</type>),
11523 (
<type>point
</type>,
<type>line
</type>),
11524 (
<type>lseg
</type>,
<type>box
</type>),
11525 (
<type>lseg
</type>,
<type>lseg
</type>),
11526 (
<type>line
</type>,
<type>lseg
</type>).
11529 <literal>point '(
0,
0)' ## lseg '[(
2,
0),(
0,
2)]'
</literal>
11530 <returnvalue>(
1,
1)
</returnvalue>
11535 <entry role=
"func_table_entry"><para role=
"func_signature">
11536 <replaceable>geometric_type
</replaceable> <literal><-
></literal> <replaceable>geometric_type
</replaceable>
11537 <returnvalue>double precision
</returnvalue>
11540 Computes the distance between the objects.
11541 Available for all seven geometric types, for all combinations
11542 of
<type>point
</type> with another geometric type, and for
11543 these additional pairs of types:
11544 (
<type>box
</type>,
<type>lseg
</type>),
11545 (
<type>lseg
</type>,
<type>line
</type>),
11546 (
<type>polygon
</type>,
<type>circle
</type>)
11547 (and the commutator cases).
11550 <literal>circle '
<(
0,
0),
1>'
<-
> circle '
<(
5,
0),
1>'
</literal>
11551 <returnvalue>3</returnvalue>
11556 <entry role=
"func_table_entry"><para role=
"func_signature">
11557 <replaceable>geometric_type
</replaceable> <literal>@
></literal> <replaceable>geometric_type
</replaceable>
11558 <returnvalue>boolean
</returnvalue>
11561 Does first object contain second?
11562 Available for these pairs of types:
11563 (
<literal>box
</literal>,
<literal>point
</literal>),
11564 (
<literal>box
</literal>,
<literal>box
</literal>),
11565 (
<literal>path
</literal>,
<literal>point
</literal>),
11566 (
<literal>polygon
</literal>,
<literal>point
</literal>),
11567 (
<literal>polygon
</literal>,
<literal>polygon
</literal>),
11568 (
<literal>circle
</literal>,
<literal>point
</literal>),
11569 (
<literal>circle
</literal>,
<literal>circle
</literal>).
11572 <literal>circle '
<(
0,
0),
2>' @
> point '(
1,
1)'
</literal>
11573 <returnvalue>t
</returnvalue>
11578 <entry role=
"func_table_entry"><para role=
"func_signature">
11579 <replaceable>geometric_type
</replaceable> <literal><@
</literal> <replaceable>geometric_type
</replaceable>
11580 <returnvalue>boolean
</returnvalue>
11583 Is first object contained in or on second?
11584 Available for these pairs of types:
11585 (
<literal>point
</literal>,
<literal>box
</literal>),
11586 (
<literal>point
</literal>,
<literal>lseg
</literal>),
11587 (
<literal>point
</literal>,
<literal>line
</literal>),
11588 (
<literal>point
</literal>,
<literal>path
</literal>),
11589 (
<literal>point
</literal>,
<literal>polygon
</literal>),
11590 (
<literal>point
</literal>,
<literal>circle
</literal>),
11591 (
<literal>box
</literal>,
<literal>box
</literal>),
11592 (
<literal>lseg
</literal>,
<literal>box
</literal>),
11593 (
<literal>lseg
</literal>,
<literal>line
</literal>),
11594 (
<literal>polygon
</literal>,
<literal>polygon
</literal>),
11595 (
<literal>circle
</literal>,
<literal>circle
</literal>).
11598 <literal>point '(
1,
1)'
<@ circle '
<(
0,
0),
2>'
</literal>
11599 <returnvalue>t
</returnvalue>
11604 <entry role=
"func_table_entry"><para role=
"func_signature">
11605 <replaceable>geometric_type
</replaceable> <literal>&&</literal> <replaceable>geometric_type
</replaceable>
11606 <returnvalue>boolean
</returnvalue>
11609 Do these objects overlap? (One point in common makes this true.)
11610 Available for
<type>box
</type>,
<type>polygon
</type>,
11611 <type>circle
</type>.
11614 <literal>box '(
1,
1),(
0,
0)'
&& box '(
2,
2),(
0,
0)'
</literal>
11615 <returnvalue>t
</returnvalue>
11620 <entry role=
"func_table_entry"><para role=
"func_signature">
11621 <replaceable>geometric_type
</replaceable> <literal><<</literal> <replaceable>geometric_type
</replaceable>
11622 <returnvalue>boolean
</returnvalue>
11625 Is first object strictly left of second?
11626 Available for
<type>point
</type>,
<type>box
</type>,
11627 <type>polygon
</type>,
<type>circle
</type>.
11630 <literal>circle '
<(
0,
0),
1>'
<< circle '
<(
5,
0),
1>'
</literal>
11631 <returnvalue>t
</returnvalue>
11636 <entry role=
"func_table_entry"><para role=
"func_signature">
11637 <replaceable>geometric_type
</replaceable> <literal>>></literal> <replaceable>geometric_type
</replaceable>
11638 <returnvalue>boolean
</returnvalue>
11641 Is first object strictly right of second?
11642 Available for
<type>point
</type>,
<type>box
</type>,
11643 <type>polygon
</type>,
<type>circle
</type>.
11646 <literal>circle '
<(
5,
0),
1>'
>> circle '
<(
0,
0),
1>'
</literal>
11647 <returnvalue>t
</returnvalue>
11652 <entry role=
"func_table_entry"><para role=
"func_signature">
11653 <replaceable>geometric_type
</replaceable> <literal>&<</literal> <replaceable>geometric_type
</replaceable>
11654 <returnvalue>boolean
</returnvalue>
11657 Does first object not extend to the right of second?
11658 Available for
<type>box
</type>,
<type>polygon
</type>,
11659 <type>circle
</type>.
11662 <literal>box '(
1,
1),(
0,
0)'
&< box '(
2,
2),(
0,
0)'
</literal>
11663 <returnvalue>t
</returnvalue>
11668 <entry role=
"func_table_entry"><para role=
"func_signature">
11669 <replaceable>geometric_type
</replaceable> <literal>&></literal> <replaceable>geometric_type
</replaceable>
11670 <returnvalue>boolean
</returnvalue>
11673 Does first object not extend to the left of second?
11674 Available for
<type>box
</type>,
<type>polygon
</type>,
11675 <type>circle
</type>.
11678 <literal>box '(
3,
3),(
0,
0)'
&> box '(
2,
2),(
0,
0)'
</literal>
11679 <returnvalue>t
</returnvalue>
11684 <entry role=
"func_table_entry"><para role=
"func_signature">
11685 <replaceable>geometric_type
</replaceable> <literal><<|
</literal> <replaceable>geometric_type
</replaceable>
11686 <returnvalue>boolean
</returnvalue>
11689 Is first object strictly below second?
11690 Available for
<type>point
</type>,
<type>box
</type>,
<type>polygon
</type>,
11691 <type>circle
</type>.
11694 <literal>box '(
3,
3),(
0,
0)'
<<| box '(
5,
5),(
3,
4)'
</literal>
11695 <returnvalue>t
</returnvalue>
11700 <entry role=
"func_table_entry"><para role=
"func_signature">
11701 <replaceable>geometric_type
</replaceable> <literal>|
>></literal> <replaceable>geometric_type
</replaceable>
11702 <returnvalue>boolean
</returnvalue>
11705 Is first object strictly above second?
11706 Available for
<type>point
</type>,
<type>box
</type>,
<type>polygon
</type>,
11707 <type>circle
</type>.
11710 <literal>box '(
5,
5),(
3,
4)' |
>> box '(
3,
3),(
0,
0)'
</literal>
11711 <returnvalue>t
</returnvalue>
11716 <entry role=
"func_table_entry"><para role=
"func_signature">
11717 <replaceable>geometric_type
</replaceable> <literal>&<|
</literal> <replaceable>geometric_type
</replaceable>
11718 <returnvalue>boolean
</returnvalue>
11721 Does first object not extend above second?
11722 Available for
<type>box
</type>,
<type>polygon
</type>,
11723 <type>circle
</type>.
11726 <literal>box '(
1,
1),(
0,
0)'
&<| box '(
2,
2),(
0,
0)'
</literal>
11727 <returnvalue>t
</returnvalue>
11732 <entry role=
"func_table_entry"><para role=
"func_signature">
11733 <replaceable>geometric_type
</replaceable> <literal>|
&></literal> <replaceable>geometric_type
</replaceable>
11734 <returnvalue>boolean
</returnvalue>
11737 Does first object not extend below second?
11738 Available for
<type>box
</type>,
<type>polygon
</type>,
11739 <type>circle
</type>.
11742 <literal>box '(
3,
3),(
0,
0)' |
&> box '(
2,
2),(
0,
0)'
</literal>
11743 <returnvalue>t
</returnvalue>
11748 <entry role=
"func_table_entry"><para role=
"func_signature">
11749 <type>box
</type> <literal><^
</literal> <type>box
</type>
11750 <returnvalue>boolean
</returnvalue>
11753 Is first object below second (allows edges to touch)?
11756 <literal>box '((
1,
1),(
0,
0))'
<^ box '((
2,
2),(
1,
1))'
</literal>
11757 <returnvalue>t
</returnvalue>
11762 <entry role=
"func_table_entry"><para role=
"func_signature">
11763 <type>box
</type> <literal>>^
</literal> <type>box
</type>
11764 <returnvalue>boolean
</returnvalue>
11767 Is first object above second (allows edges to touch)?
11770 <literal>box '((
2,
2),(
1,
1))'
>^ box '((
1,
1),(
0,
0))'
</literal>
11771 <returnvalue>t
</returnvalue>
11776 <entry role=
"func_table_entry"><para role=
"func_signature">
11777 <replaceable>geometric_type
</replaceable> <literal>?#
</literal> <replaceable>geometric_type
</replaceable>
11778 <returnvalue>boolean
</returnvalue>
11781 Do these objects intersect?
11782 Available for these pairs of types:
11783 (
<type>box
</type>,
<type>box
</type>),
11784 (
<type>lseg
</type>,
<type>box
</type>),
11785 (
<type>lseg
</type>,
<type>lseg
</type>),
11786 (
<type>lseg
</type>,
<type>line
</type>),
11787 (
<type>line
</type>,
<type>box
</type>),
11788 (
<type>line
</type>,
<type>line
</type>),
11789 (
<type>path
</type>,
<type>path
</type>).
11792 <literal>lseg '[(-
1,
0),(
1,
0)]' ?# box '(
2,
2),(-
2,-
2)'
</literal>
11793 <returnvalue>t
</returnvalue>
11798 <entry role=
"func_table_entry"><para role=
"func_signature">
11799 <literal>?-
</literal> <type>line
</type>
11800 <returnvalue>boolean
</returnvalue>
11802 <para role=
"func_signature">
11803 <literal>?-
</literal> <type>lseg
</type>
11804 <returnvalue>boolean
</returnvalue>
11807 Is line horizontal?
11810 <literal>?- lseg '[(-
1,
0),(
1,
0)]'
</literal>
11811 <returnvalue>t
</returnvalue>
11816 <entry role=
"func_table_entry"><para role=
"func_signature">
11817 <type>point
</type> <literal>?-
</literal> <type>point
</type>
11818 <returnvalue>boolean
</returnvalue>
11821 Are points horizontally aligned (that is, have same y coordinate)?
11824 <literal>point '(
1,
0)' ?- point '(
0,
0)'
</literal>
11825 <returnvalue>t
</returnvalue>
11830 <entry role=
"func_table_entry"><para role=
"func_signature">
11831 <literal>?|
</literal> <type>line
</type>
11832 <returnvalue>boolean
</returnvalue>
11834 <para role=
"func_signature">
11835 <literal>?|
</literal> <type>lseg
</type>
11836 <returnvalue>boolean
</returnvalue>
11842 <literal>?| lseg '[(-
1,
0),(
1,
0)]'
</literal>
11843 <returnvalue>f
</returnvalue>
11848 <entry role=
"func_table_entry"><para role=
"func_signature">
11849 <type>point
</type> <literal>?|
</literal> <type>point
</type>
11850 <returnvalue>boolean
</returnvalue>
11853 Are points vertically aligned (that is, have same x coordinate)?
11856 <literal>point '(
0,
1)' ?| point '(
0,
0)'
</literal>
11857 <returnvalue>t
</returnvalue>
11862 <entry role=
"func_table_entry"><para role=
"func_signature">
11863 <type>line
</type> <literal>?-|
</literal> <type>line
</type>
11864 <returnvalue>boolean
</returnvalue>
11866 <para role=
"func_signature">
11867 <type>lseg
</type> <literal>?-|
</literal> <type>lseg
</type>
11868 <returnvalue>boolean
</returnvalue>
11871 Are lines perpendicular?
11874 <literal>lseg '[(
0,
0),(
0,
1)]' ?-| lseg '[(
0,
0),(
1,
0)]'
</literal>
11875 <returnvalue>t
</returnvalue>
11880 <entry role=
"func_table_entry"><para role=
"func_signature">
11881 <type>line
</type> <literal>?||
</literal> <type>line
</type>
11882 <returnvalue>boolean
</returnvalue>
11884 <para role=
"func_signature">
11885 <type>lseg
</type> <literal>?||
</literal> <type>lseg
</type>
11886 <returnvalue>boolean
</returnvalue>
11889 Are lines parallel?
11892 <literal>lseg '[(-
1,
0),(
1,
0)]' ?|| lseg '[(-
1,
2),(
1,
2)]'
</literal>
11893 <returnvalue>t
</returnvalue>
11898 <entry role=
"func_table_entry"><para role=
"func_signature">
11899 <replaceable>geometric_type
</replaceable> <literal>~=
</literal> <replaceable>geometric_type
</replaceable>
11900 <returnvalue>boolean
</returnvalue>
11903 Are these objects the same?
11904 Available for
<type>point
</type>,
<type>box
</type>,
11905 <type>polygon
</type>,
<type>circle
</type>.
11908 <literal>polygon '((
0,
0),(
1,
1))' ~= polygon '((
1,
1),(
0,
0))'
</literal>
11909 <returnvalue>t
</returnvalue>
11918 Note that the
<quote>same as
</quote> operator,
<literal>~=
</literal>,
11919 represents the usual notion of equality for the
<type>point
</type>,
11920 <type>box
</type>,
<type>polygon
</type>, and
<type>circle
</type> types.
11921 Some of the geometric types also have an
<literal>=
</literal> operator, but
11922 <literal>=
</literal> compares for equal
<emphasis>areas
</emphasis> only.
11923 The other scalar comparison operators (
<literal><=
</literal> and so
11924 on), where available for these types, likewise compare areas.
11930 Before
<productname>PostgreSQL
</productname> 14, the point
11931 is strictly below/above comparison operators
<type>point
</type>
11932 <literal><<|
</literal> <type>point
</type> and
<type>point
</type>
11933 <literal>|
>></literal> <type>point
</type> were respectively
11934 called
<literal><^
</literal> and
<literal>>^
</literal>. These
11935 names are still available, but are deprecated and will eventually be
11940 <table id=
"functions-geometry-func-table">
11941 <title>Geometric Functions
</title>
11945 <entry role=
"func_table_entry"><para role=
"func_signature">
11959 <entry role=
"func_table_entry"><para role=
"func_signature">
11961 <primary>area
</primary>
11963 <function>area
</function> (
<replaceable>geometric_type
</replaceable> )
11964 <returnvalue>double precision
</returnvalue>
11968 Available for
<type>box
</type>,
<type>path
</type>,
<type>circle
</type>.
11969 A
<type>path
</type> input must be closed, else NULL is returned.
11970 Also, if the
<type>path
</type> is self-intersecting, the result may be
11974 <literal>area(box '(
2,
2),(
0,
0)')
</literal>
11975 <returnvalue>4</returnvalue>
11980 <entry role=
"func_table_entry"><para role=
"func_signature">
11982 <primary>center
</primary>
11984 <function>center
</function> (
<replaceable>geometric_type
</replaceable> )
11985 <returnvalue>point
</returnvalue>
11988 Computes center point.
11989 Available for
<type>box
</type>,
<type>circle
</type>.
11992 <literal>center(box '(
1,
2),(
0,
0)')
</literal>
11993 <returnvalue>(
0.5,
1)
</returnvalue>
11998 <entry role=
"func_table_entry"><para role=
"func_signature">
12000 <primary>diagonal
</primary>
12002 <function>diagonal
</function> (
<type>box
</type> )
12003 <returnvalue>lseg
</returnvalue>
12006 Extracts box's diagonal as a line segment
12007 (same as
<function>lseg(box)
</function>).
12010 <literal>diagonal(box '(
1,
2),(
0,
0)')
</literal>
12011 <returnvalue>[(
1,
2),(
0,
0)]
</returnvalue>
12016 <entry role=
"func_table_entry"><para role=
"func_signature">
12018 <primary>diameter
</primary>
12020 <function>diameter
</function> (
<type>circle
</type> )
12021 <returnvalue>double precision
</returnvalue>
12024 Computes diameter of circle.
12027 <literal>diameter(circle '
<(
0,
0),
2>')
</literal>
12028 <returnvalue>4</returnvalue>
12033 <entry role=
"func_table_entry"><para role=
"func_signature">
12035 <primary>height
</primary>
12037 <function>height
</function> (
<type>box
</type> )
12038 <returnvalue>double precision
</returnvalue>
12041 Computes vertical size of box.
12044 <literal>height(box '(
1,
2),(
0,
0)')
</literal>
12045 <returnvalue>2</returnvalue>
12050 <entry role=
"func_table_entry"><para role=
"func_signature">
12052 <primary>isclosed
</primary>
12054 <function>isclosed
</function> (
<type>path
</type> )
12055 <returnvalue>boolean
</returnvalue>
12061 <literal>isclosed(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12062 <returnvalue>t
</returnvalue>
12067 <entry role=
"func_table_entry"><para role=
"func_signature">
12069 <primary>isopen
</primary>
12071 <function>isopen
</function> (
<type>path
</type> )
12072 <returnvalue>boolean
</returnvalue>
12078 <literal>isopen(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
12079 <returnvalue>t
</returnvalue>
12084 <entry role=
"func_table_entry"><para role=
"func_signature">
12086 <primary>length
</primary>
12088 <function>length
</function> (
<replaceable>geometric_type
</replaceable> )
12089 <returnvalue>double precision
</returnvalue>
12092 Computes the total length.
12093 Available for
<type>lseg
</type>,
<type>path
</type>.
12096 <literal>length(path '((-
1,
0),(
1,
0))')
</literal>
12097 <returnvalue>4</returnvalue>
12102 <entry role=
"func_table_entry"><para role=
"func_signature">
12104 <primary>npoints
</primary>
12106 <function>npoints
</function> (
<replaceable>geometric_type
</replaceable> )
12107 <returnvalue>integer
</returnvalue>
12110 Returns the number of points.
12111 Available for
<type>path
</type>,
<type>polygon
</type>.
12114 <literal>npoints(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
12115 <returnvalue>3</returnvalue>
12120 <entry role=
"func_table_entry"><para role=
"func_signature">
12122 <primary>pclose
</primary>
12124 <function>pclose
</function> (
<type>path
</type> )
12125 <returnvalue>path
</returnvalue>
12128 Converts path to closed form.
12131 <literal>pclose(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
12132 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12137 <entry role=
"func_table_entry"><para role=
"func_signature">
12139 <primary>popen
</primary>
12141 <function>popen
</function> (
<type>path
</type> )
12142 <returnvalue>path
</returnvalue>
12145 Converts path to open form.
12148 <literal>popen(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12149 <returnvalue>[(
0,
0),(
1,
1),(
2,
0)]
</returnvalue>
12154 <entry role=
"func_table_entry"><para role=
"func_signature">
12156 <primary>radius
</primary>
12158 <function>radius
</function> (
<type>circle
</type> )
12159 <returnvalue>double precision
</returnvalue>
12162 Computes radius of circle.
12165 <literal>radius(circle '
<(
0,
0),
2>')
</literal>
12166 <returnvalue>2</returnvalue>
12171 <entry role=
"func_table_entry"><para role=
"func_signature">
12173 <primary>slope
</primary>
12175 <function>slope
</function> (
<type>point
</type>,
<type>point
</type> )
12176 <returnvalue>double precision
</returnvalue>
12179 Computes slope of a line drawn through the two points.
12182 <literal>slope(point '(
0,
0)', point '(
2,
1)')
</literal>
12183 <returnvalue>0.5</returnvalue>
12188 <entry role=
"func_table_entry"><para role=
"func_signature">
12190 <primary>width
</primary>
12192 <function>width
</function> (
<type>box
</type> )
12193 <returnvalue>double precision
</returnvalue>
12196 Computes horizontal size of box.
12199 <literal>width(box '(
1,
2),(
0,
0)')
</literal>
12200 <returnvalue>1</returnvalue>
12207 <table id=
"functions-geometry-conv-table">
12208 <title>Geometric Type Conversion Functions
</title>
12212 <entry role=
"func_table_entry"><para role=
"func_signature">
12226 <entry role=
"func_table_entry"><para role=
"func_signature">
12228 <primary>box
</primary>
12230 <function>box
</function> (
<type>circle
</type> )
12231 <returnvalue>box
</returnvalue>
12234 Computes box inscribed within the circle.
12237 <literal>box(circle '
<(
0,
0),
2>')
</literal>
12238 <returnvalue>(
1.414213562373095,
1.414213562373095),
&zwsp;(-
1.414213562373095,-
1.414213562373095)
</returnvalue>
12243 <entry role=
"func_table_entry"><para role=
"func_signature">
12244 <function>box
</function> (
<type>point
</type> )
12245 <returnvalue>box
</returnvalue>
12248 Converts point to empty box.
12251 <literal>box(point '(
1,
0)')
</literal>
12252 <returnvalue>(
1,
0),(
1,
0)
</returnvalue>
12257 <entry role=
"func_table_entry"><para role=
"func_signature">
12258 <function>box
</function> (
<type>point
</type>,
<type>point
</type> )
12259 <returnvalue>box
</returnvalue>
12262 Converts any two corner points to box.
12265 <literal>box(point '(
0,
1)', point '(
1,
0)')
</literal>
12266 <returnvalue>(
1,
1),(
0,
0)
</returnvalue>
12271 <entry role=
"func_table_entry"><para role=
"func_signature">
12272 <function>box
</function> (
<type>polygon
</type> )
12273 <returnvalue>box
</returnvalue>
12276 Computes bounding box of polygon.
12279 <literal>box(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12280 <returnvalue>(
2,
1),(
0,
0)
</returnvalue>
12285 <entry role=
"func_table_entry"><para role=
"func_signature">
12287 <primary>bound_box
</primary>
12289 <function>bound_box
</function> (
<type>box
</type>,
<type>box
</type> )
12290 <returnvalue>box
</returnvalue>
12293 Computes bounding box of two boxes.
12296 <literal>bound_box(box '(
1,
1),(
0,
0)', box '(
4,
4),(
3,
3)')
</literal>
12297 <returnvalue>(
4,
4),(
0,
0)
</returnvalue>
12302 <entry role=
"func_table_entry"><para role=
"func_signature">
12304 <primary>circle
</primary>
12306 <function>circle
</function> (
<type>box
</type> )
12307 <returnvalue>circle
</returnvalue>
12310 Computes smallest circle enclosing box.
12313 <literal>circle(box '(
1,
1),(
0,
0)')
</literal>
12314 <returnvalue><(
0.5,
0.5),
0.7071067811865476></returnvalue>
12319 <entry role=
"func_table_entry"><para role=
"func_signature">
12320 <function>circle
</function> (
<type>point
</type>,
<type>double precision
</type> )
12321 <returnvalue>circle
</returnvalue>
12324 Constructs circle from center and radius.
12327 <literal>circle(point '(
0,
0)',
2.0)
</literal>
12328 <returnvalue><(
0,
0),
2></returnvalue>
12333 <entry role=
"func_table_entry"><para role=
"func_signature">
12334 <function>circle
</function> (
<type>polygon
</type> )
12335 <returnvalue>circle
</returnvalue>
12338 Converts polygon to circle. The circle's center is the mean of the
12339 positions of the polygon's points, and the radius is the average
12340 distance of the polygon's points from that center.
12343 <literal>circle(polygon '((
0,
0),(
1,
3),(
2,
0))')
</literal>
12344 <returnvalue><(
1,
1),
1.6094757082487299></returnvalue>
12349 <entry role=
"func_table_entry"><para role=
"func_signature">
12351 <primary>line
</primary>
12353 <function>line
</function> (
<type>point
</type>,
<type>point
</type> )
12354 <returnvalue>line
</returnvalue>
12357 Converts two points to the line through them.
12360 <literal>line(point '(-
1,
0)', point '(
1,
0)')
</literal>
12361 <returnvalue>{
0,-
1,
0}
</returnvalue>
12366 <entry role=
"func_table_entry"><para role=
"func_signature">
12368 <primary>lseg
</primary>
12370 <function>lseg
</function> (
<type>box
</type> )
12371 <returnvalue>lseg
</returnvalue>
12374 Extracts box's diagonal as a line segment.
12377 <literal>lseg(box '(
1,
0),(-
1,
0)')
</literal>
12378 <returnvalue>[(
1,
0),(-
1,
0)]
</returnvalue>
12383 <entry role=
"func_table_entry"><para role=
"func_signature">
12384 <function>lseg
</function> (
<type>point
</type>,
<type>point
</type> )
12385 <returnvalue>lseg
</returnvalue>
12388 Constructs line segment from two endpoints.
12391 <literal>lseg(point '(-
1,
0)', point '(
1,
0)')
</literal>
12392 <returnvalue>[(-
1,
0),(
1,
0)]
</returnvalue>
12397 <entry role=
"func_table_entry"><para role=
"func_signature">
12399 <primary>path
</primary>
12401 <function>path
</function> (
<type>polygon
</type> )
12402 <returnvalue>path
</returnvalue>
12405 Converts polygon to a closed path with the same list of points.
12408 <literal>path(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12409 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12414 <entry role=
"func_table_entry"><para role=
"func_signature">
12416 <primary>point
</primary>
12418 <function>point
</function> (
<type>double precision
</type>,
<type>double precision
</type> )
12419 <returnvalue>point
</returnvalue>
12422 Constructs point from its coordinates.
12425 <literal>point(
23.4, -
44.5)
</literal>
12426 <returnvalue>(
23.4,-
44.5)
</returnvalue>
12431 <entry role=
"func_table_entry"><para role=
"func_signature">
12432 <function>point
</function> (
<type>box
</type> )
12433 <returnvalue>point
</returnvalue>
12436 Computes center of box.
12439 <literal>point(box '(
1,
0),(-
1,
0)')
</literal>
12440 <returnvalue>(
0,
0)
</returnvalue>
12445 <entry role=
"func_table_entry"><para role=
"func_signature">
12446 <function>point
</function> (
<type>circle
</type> )
12447 <returnvalue>point
</returnvalue>
12450 Computes center of circle.
12453 <literal>point(circle '
<(
0,
0),
2>')
</literal>
12454 <returnvalue>(
0,
0)
</returnvalue>
12459 <entry role=
"func_table_entry"><para role=
"func_signature">
12460 <function>point
</function> (
<type>lseg
</type> )
12461 <returnvalue>point
</returnvalue>
12464 Computes center of line segment.
12467 <literal>point(lseg '[(-
1,
0),(
1,
0)]')
</literal>
12468 <returnvalue>(
0,
0)
</returnvalue>
12473 <entry role=
"func_table_entry"><para role=
"func_signature">
12474 <function>point
</function> (
<type>polygon
</type> )
12475 <returnvalue>point
</returnvalue>
12478 Computes center of polygon (the mean of the
12479 positions of the polygon's points).
12482 <literal>point(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12483 <returnvalue>(
1,
0.3333333333333333)
</returnvalue>
12488 <entry role=
"func_table_entry"><para role=
"func_signature">
12490 <primary>polygon
</primary>
12492 <function>polygon
</function> (
<type>box
</type> )
12493 <returnvalue>polygon
</returnvalue>
12496 Converts box to a
4-point polygon.
12499 <literal>polygon(box '(
1,
1),(
0,
0)')
</literal>
12500 <returnvalue>((
0,
0),(
0,
1),(
1,
1),(
1,
0))
</returnvalue>
12505 <entry role=
"func_table_entry"><para role=
"func_signature">
12506 <function>polygon
</function> (
<type>circle
</type> )
12507 <returnvalue>polygon
</returnvalue>
12510 Converts circle to a
12-point polygon.
12513 <literal>polygon(circle '
<(
0,
0),
2>')
</literal>
12514 <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>
12519 <entry role=
"func_table_entry"><para role=
"func_signature">
12520 <function>polygon
</function> (
<type>integer
</type>,
<type>circle
</type> )
12521 <returnvalue>polygon
</returnvalue>
12524 Converts circle to an
<replaceable>n
</replaceable>-point polygon.
12527 <literal>polygon(
4, circle '
<(
3,
0),
1>')
</literal>
12528 <returnvalue>((
2,
0),
&zwsp;(
3,
1),
&zwsp;(
4,
1.2246063538223773e-16),
&zwsp;(
3,-
1))
</returnvalue>
12533 <entry role=
"func_table_entry"><para role=
"func_signature">
12534 <function>polygon
</function> (
<type>path
</type> )
12535 <returnvalue>polygon
</returnvalue>
12538 Converts closed path to a polygon with the same list of points.
12541 <literal>polygon(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12542 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12551 It is possible to access the two component numbers of a
<type>point
</type>
12552 as though the point were an array with indexes
0 and
1. For example, if
12553 <literal>t.p
</literal> is a
<type>point
</type> column then
12554 <literal>SELECT p[
0] FROM t
</literal> retrieves the X coordinate and
12555 <literal>UPDATE t SET p[
1] = ...
</literal> changes the Y coordinate.
12556 In the same way, a value of type
<type>box
</type> or
<type>lseg
</type> can be treated
12557 as an array of two
<type>point
</type> values.
12563 <sect1 id=
"functions-net">
12564 <title>Network Address Functions and Operators
</title>
12567 The IP network address types,
<type>cidr
</type> and
<type>inet
</type>,
12568 support the usual comparison operators shown in
12569 <xref linkend=
"functions-comparison-op-table"/>
12570 as well as the specialized operators and functions shown in
12571 <xref linkend=
"cidr-inet-operators-table"/> and
12572 <xref linkend=
"cidr-inet-functions-table"/>.
12576 Any
<type>cidr
</type> value can be cast to
<type>inet
</type> implicitly;
12577 therefore, the operators and functions shown below as operating on
12578 <type>inet
</type> also work on
<type>cidr
</type> values. (Where there are
12579 separate functions for
<type>inet
</type> and
<type>cidr
</type>, it is
12580 because the behavior should be different for the two cases.)
12581 Also, it is permitted to cast an
<type>inet
</type> value
12582 to
<type>cidr
</type>. When this is done, any bits to the right of the
12583 netmask are silently zeroed to create a valid
<type>cidr
</type> value.
12586 <table id=
"cidr-inet-operators-table">
12587 <title>IP Address Operators
</title>
12591 <entry role=
"func_table_entry"><para role=
"func_signature">
12605 <entry role=
"func_table_entry"><para role=
"func_signature">
12606 <type>inet
</type> <literal><<</literal> <type>inet
</type>
12607 <returnvalue>boolean
</returnvalue>
12610 Is subnet strictly contained by subnet?
12611 This operator, and the next four, test for subnet inclusion. They
12612 consider only the network parts of the two addresses (ignoring any
12613 bits to the right of the netmasks) and determine whether one network
12614 is identical to or a subnet of the other.
12617 <literal>inet '
192.168.1.5'
<< inet '
192.168.1/
24'
</literal>
12618 <returnvalue>t
</returnvalue>
12621 <literal>inet '
192.168.0.5'
<< inet '
192.168.1/
24'
</literal>
12622 <returnvalue>f
</returnvalue>
12625 <literal>inet '
192.168.1/
24'
<< inet '
192.168.1/
24'
</literal>
12626 <returnvalue>f
</returnvalue>
12631 <entry role=
"func_table_entry"><para role=
"func_signature">
12632 <type>inet
</type> <literal><<=
</literal> <type>inet
</type>
12633 <returnvalue>boolean
</returnvalue>
12636 Is subnet contained by or equal to subnet?
12639 <literal>inet '
192.168.1/
24'
<<= inet '
192.168.1/
24'
</literal>
12640 <returnvalue>t
</returnvalue>
12645 <entry role=
"func_table_entry"><para role=
"func_signature">
12646 <type>inet
</type> <literal>>></literal> <type>inet
</type>
12647 <returnvalue>boolean
</returnvalue>
12650 Does subnet strictly contain subnet?
12653 <literal>inet '
192.168.1/
24'
>> inet '
192.168.1.5'
</literal>
12654 <returnvalue>t
</returnvalue>
12659 <entry role=
"func_table_entry"><para role=
"func_signature">
12660 <type>inet
</type> <literal>>>=
</literal> <type>inet
</type>
12661 <returnvalue>boolean
</returnvalue>
12664 Does subnet contain or equal subnet?
12667 <literal>inet '
192.168.1/
24'
>>= inet '
192.168.1/
24'
</literal>
12668 <returnvalue>t
</returnvalue>
12673 <entry role=
"func_table_entry"><para role=
"func_signature">
12674 <type>inet
</type> <literal>&&</literal> <type>inet
</type>
12675 <returnvalue>boolean
</returnvalue>
12678 Does either subnet contain or equal the other?
12681 <literal>inet '
192.168.1/
24'
&& inet '
192.168.1.80/
28'
</literal>
12682 <returnvalue>t
</returnvalue>
12685 <literal>inet '
192.168.1/
24'
&& inet '
192.168.2.0/
28'
</literal>
12686 <returnvalue>f
</returnvalue>
12691 <entry role=
"func_table_entry"><para role=
"func_signature">
12692 <literal>~
</literal> <type>inet
</type>
12693 <returnvalue>inet
</returnvalue>
12696 Computes bitwise NOT.
12699 <literal>~ inet '
192.168.1.6'
</literal>
12700 <returnvalue>63.87.254.249</returnvalue>
12705 <entry role=
"func_table_entry"><para role=
"func_signature">
12706 <type>inet
</type> <literal>&</literal> <type>inet
</type>
12707 <returnvalue>inet
</returnvalue>
12710 Computes bitwise AND.
12713 <literal>inet '
192.168.1.6'
& inet '
0.0.0.255'
</literal>
12714 <returnvalue>0.0.0.6</returnvalue>
12719 <entry role=
"func_table_entry"><para role=
"func_signature">
12720 <type>inet
</type> <literal>|
</literal> <type>inet
</type>
12721 <returnvalue>inet
</returnvalue>
12724 Computes bitwise OR.
12727 <literal>inet '
192.168.1.6' | inet '
0.0.0.255'
</literal>
12728 <returnvalue>192.168.1.255</returnvalue>
12733 <entry role=
"func_table_entry"><para role=
"func_signature">
12734 <type>inet
</type> <literal>+
</literal> <type>bigint
</type>
12735 <returnvalue>inet
</returnvalue>
12738 Adds an offset to an address.
12741 <literal>inet '
192.168.1.6' +
25</literal>
12742 <returnvalue>192.168.1.31</returnvalue>
12747 <entry role=
"func_table_entry"><para role=
"func_signature">
12748 <type>bigint
</type> <literal>+
</literal> <type>inet
</type>
12749 <returnvalue>inet
</returnvalue>
12752 Adds an offset to an address.
12755 <literal>200 + inet '::ffff:fff0:
1'
</literal>
12756 <returnvalue>::ffff:
255.240.0.201</returnvalue>
12761 <entry role=
"func_table_entry"><para role=
"func_signature">
12762 <type>inet
</type> <literal>-
</literal> <type>bigint
</type>
12763 <returnvalue>inet
</returnvalue>
12766 Subtracts an offset from an address.
12769 <literal>inet '
192.168.1.43' -
36</literal>
12770 <returnvalue>192.168.1.7</returnvalue>
12775 <entry role=
"func_table_entry"><para role=
"func_signature">
12776 <type>inet
</type> <literal>-
</literal> <type>inet
</type>
12777 <returnvalue>bigint
</returnvalue>
12780 Computes the difference of two addresses.
12783 <literal>inet '
192.168.1.43' - inet '
192.168.1.19'
</literal>
12784 <returnvalue>24</returnvalue>
12787 <literal>inet '::
1' - inet '::ffff:
1'
</literal>
12788 <returnvalue>-
4294901760</returnvalue>
12795 <table id=
"cidr-inet-functions-table">
12796 <title>IP Address Functions
</title>
12800 <entry role=
"func_table_entry"><para role=
"func_signature">
12814 <entry role=
"func_table_entry"><para role=
"func_signature">
12816 <primary>abbrev
</primary>
12818 <function>abbrev
</function> (
<type>inet
</type> )
12819 <returnvalue>text
</returnvalue>
12822 Creates an abbreviated display format as text.
12823 (The result is the same as the
<type>inet
</type> output function
12824 produces; it is
<quote>abbreviated
</quote> only in comparison to the
12825 result of an explicit cast to
<type>text
</type>, which for historical
12826 reasons will never suppress the netmask part.)
12829 <literal>abbrev(inet '
10.1.0.0/
32')
</literal>
12830 <returnvalue>10.1.0.0</returnvalue>
12835 <entry role=
"func_table_entry"><para role=
"func_signature">
12836 <function>abbrev
</function> (
<type>cidr
</type> )
12837 <returnvalue>text
</returnvalue>
12840 Creates an abbreviated display format as text.
12841 (The abbreviation consists of dropping all-zero octets to the right
12842 of the netmask; more examples are in
12843 <xref linkend=
"datatype-net-cidr-table"/>.)
12846 <literal>abbrev(cidr '
10.1.0.0/
16')
</literal>
12847 <returnvalue>10.1/
16</returnvalue>
12852 <entry role=
"func_table_entry"><para role=
"func_signature">
12854 <primary>broadcast
</primary>
12856 <function>broadcast
</function> (
<type>inet
</type> )
12857 <returnvalue>inet
</returnvalue>
12860 Computes the broadcast address for the address's network.
12863 <literal>broadcast(inet '
192.168.1.5/
24')
</literal>
12864 <returnvalue>192.168.1.255/
24</returnvalue>
12869 <entry role=
"func_table_entry"><para role=
"func_signature">
12871 <primary>family
</primary>
12873 <function>family
</function> (
<type>inet
</type> )
12874 <returnvalue>integer
</returnvalue>
12877 Returns the address's family:
<literal>4</literal> for IPv4,
12878 <literal>6</literal> for IPv6.
12881 <literal>family(inet '::
1')
</literal>
12882 <returnvalue>6</returnvalue>
12887 <entry role=
"func_table_entry"><para role=
"func_signature">
12889 <primary>host
</primary>
12891 <function>host
</function> (
<type>inet
</type> )
12892 <returnvalue>text
</returnvalue>
12895 Returns the IP address as text, ignoring the netmask.
12898 <literal>host(inet '
192.168.1.0/
24')
</literal>
12899 <returnvalue>192.168.1.0</returnvalue>
12904 <entry role=
"func_table_entry"><para role=
"func_signature">
12906 <primary>hostmask
</primary>
12908 <function>hostmask
</function> (
<type>inet
</type> )
12909 <returnvalue>inet
</returnvalue>
12912 Computes the host mask for the address's network.
12915 <literal>hostmask(inet '
192.168.23.20/
30')
</literal>
12916 <returnvalue>0.0.0.3</returnvalue>
12921 <entry role=
"func_table_entry"><para role=
"func_signature">
12923 <primary>inet_merge
</primary>
12925 <function>inet_merge
</function> (
<type>inet
</type>,
<type>inet
</type> )
12926 <returnvalue>cidr
</returnvalue>
12929 Computes the smallest network that includes both of the given networks.
12932 <literal>inet_merge(inet '
192.168.1.5/
24', inet '
192.168.2.5/
24')
</literal>
12933 <returnvalue>192.168.0.0/
22</returnvalue>
12938 <entry role=
"func_table_entry"><para role=
"func_signature">
12940 <primary>inet_same_family
</primary>
12942 <function>inet_same_family
</function> (
<type>inet
</type>,
<type>inet
</type> )
12943 <returnvalue>boolean
</returnvalue>
12946 Tests whether the addresses belong to the same IP family.
12949 <literal>inet_same_family(inet '
192.168.1.5/
24', inet '::
1')
</literal>
12950 <returnvalue>f
</returnvalue>
12955 <entry role=
"func_table_entry"><para role=
"func_signature">
12957 <primary>masklen
</primary>
12959 <function>masklen
</function> (
<type>inet
</type> )
12960 <returnvalue>integer
</returnvalue>
12963 Returns the netmask length in bits.
12966 <literal>masklen(inet '
192.168.1.5/
24')
</literal>
12967 <returnvalue>24</returnvalue>
12972 <entry role=
"func_table_entry"><para role=
"func_signature">
12974 <primary>netmask
</primary>
12976 <function>netmask
</function> (
<type>inet
</type> )
12977 <returnvalue>inet
</returnvalue>
12980 Computes the network mask for the address's network.
12983 <literal>netmask(inet '
192.168.1.5/
24')
</literal>
12984 <returnvalue>255.255.255.0</returnvalue>
12989 <entry role=
"func_table_entry"><para role=
"func_signature">
12991 <primary>network
</primary>
12993 <function>network
</function> (
<type>inet
</type> )
12994 <returnvalue>cidr
</returnvalue>
12997 Returns the network part of the address, zeroing out
12998 whatever is to the right of the netmask.
12999 (This is equivalent to casting the value to
<type>cidr
</type>.)
13002 <literal>network(inet '
192.168.1.5/
24')
</literal>
13003 <returnvalue>192.168.1.0/
24</returnvalue>
13008 <entry role=
"func_table_entry"><para role=
"func_signature">
13010 <primary>set_masklen
</primary>
13012 <function>set_masklen
</function> (
<type>inet
</type>,
<type>integer
</type> )
13013 <returnvalue>inet
</returnvalue>
13016 Sets the netmask length for an
<type>inet
</type> value.
13017 The address part does not change.
13020 <literal>set_masklen(inet '
192.168.1.5/
24',
16)
</literal>
13021 <returnvalue>192.168.1.5/
16</returnvalue>
13026 <entry role=
"func_table_entry"><para role=
"func_signature">
13027 <function>set_masklen
</function> (
<type>cidr
</type>,
<type>integer
</type> )
13028 <returnvalue>cidr
</returnvalue>
13031 Sets the netmask length for a
<type>cidr
</type> value.
13032 Address bits to the right of the new netmask are set to zero.
13035 <literal>set_masklen(cidr '
192.168.1.0/
24',
16)
</literal>
13036 <returnvalue>192.168.0.0/
16</returnvalue>
13041 <entry role=
"func_table_entry"><para role=
"func_signature">
13043 <primary>text
</primary>
13045 <function>text
</function> (
<type>inet
</type> )
13046 <returnvalue>text
</returnvalue>
13049 Returns the unabbreviated IP address and netmask length as text.
13050 (This has the same result as an explicit cast to
<type>text
</type>.)
13053 <literal>text(inet '
192.168.1.5')
</literal>
13054 <returnvalue>192.168.1.5/
32</returnvalue>
13063 The
<function>abbrev
</function>,
<function>host
</function>,
13064 and
<function>text
</function> functions are primarily intended to offer
13065 alternative display formats for IP addresses.
13070 The MAC address types,
<type>macaddr
</type> and
<type>macaddr8
</type>,
13071 support the usual comparison operators shown in
13072 <xref linkend=
"functions-comparison-op-table"/>
13073 as well as the specialized functions shown in
13074 <xref linkend=
"macaddr-functions-table"/>.
13075 In addition, they support the bitwise logical operators
13076 <literal>~
</literal>,
<literal>&</literal> and
<literal>|
</literal>
13077 (NOT, AND and OR), just as shown above for IP addresses.
13080 <table id=
"macaddr-functions-table">
13081 <title>MAC Address Functions
</title>
13085 <entry role=
"func_table_entry"><para role=
"func_signature">
13099 <entry role=
"func_table_entry"><para role=
"func_signature">
13101 <primary>trunc
</primary>
13103 <function>trunc
</function> (
<type>macaddr
</type> )
13104 <returnvalue>macaddr
</returnvalue>
13107 Sets the last
3 bytes of the address to zero. The remaining prefix
13108 can be associated with a particular manufacturer (using data not
13109 included in
<productname>PostgreSQL
</productname>).
13112 <literal>trunc(macaddr '
12:
34:
56:
78:
90:ab')
</literal>
13113 <returnvalue>12:
34:
56:
00:
00:
00</returnvalue>
13118 <entry role=
"func_table_entry"><para role=
"func_signature">
13119 <function>trunc
</function> (
<type>macaddr8
</type> )
13120 <returnvalue>macaddr8
</returnvalue>
13123 Sets the last
5 bytes of the address to zero. The remaining prefix
13124 can be associated with a particular manufacturer (using data not
13125 included in
<productname>PostgreSQL
</productname>).
13128 <literal>trunc(macaddr8 '
12:
34:
56:
78:
90:ab:cd:ef')
</literal>
13129 <returnvalue>12:
34:
56:
00:
00:
00:
00:
00</returnvalue>
13134 <entry role=
"func_table_entry"><para role=
"func_signature">
13136 <primary>macaddr8_set7bit
</primary>
13138 <function>macaddr8_set7bit
</function> (
<type>macaddr8
</type> )
13139 <returnvalue>macaddr8
</returnvalue>
13142 Sets the
7th bit of the address to one, creating what is known as
13143 modified EUI-
64, for inclusion in an IPv6 address.
13146 <literal>macaddr8_set7bit(macaddr8 '
00:
34:
56:ab:cd:ef')
</literal>
13147 <returnvalue>02:
34:
56:ff:fe:ab:cd:ef
</returnvalue>
13157 <sect1 id=
"functions-textsearch">
13158 <title>Text Search Functions and Operators
</title>
13160 <indexterm zone=
"datatype-textsearch">
13161 <primary>full text search
</primary>
13162 <secondary>functions and operators
</secondary>
13165 <indexterm zone=
"datatype-textsearch">
13166 <primary>text search
</primary>
13167 <secondary>functions and operators
</secondary>
13171 <xref linkend=
"textsearch-operators-table"/>,
13172 <xref linkend=
"textsearch-functions-table"/> and
13173 <xref linkend=
"textsearch-functions-debug-table"/>
13174 summarize the functions and operators that are provided
13175 for full text searching. See
<xref linkend=
"textsearch"/> for a detailed
13176 explanation of
<productname>PostgreSQL
</productname>'s text search
13180 <table id=
"textsearch-operators-table">
13181 <title>Text Search Operators
</title>
13185 <entry role=
"func_table_entry"><para role=
"func_signature">
13199 <entry role=
"func_table_entry"><para role=
"func_signature">
13200 <type>tsvector
</type> <literal>@@
</literal> <type>tsquery
</type>
13201 <returnvalue>boolean
</returnvalue>
13203 <para role=
"func_signature">
13204 <type>tsquery
</type> <literal>@@
</literal> <type>tsvector
</type>
13205 <returnvalue>boolean
</returnvalue>
13208 Does
<type>tsvector
</type> match
<type>tsquery
</type>?
13209 (The arguments can be given in either order.)
13212 <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat
& rat')
</literal>
13213 <returnvalue>t
</returnvalue>
13218 <entry role=
"func_table_entry"><para role=
"func_signature">
13219 <type>text
</type> <literal>@@
</literal> <type>tsquery
</type>
13220 <returnvalue>boolean
</returnvalue>
13223 Does text string, after implicit invocation
13224 of
<function>to_tsvector()
</function>, match
<type>tsquery
</type>?
13227 <literal>'fat cats ate rats' @@ to_tsquery('cat
& rat')
</literal>
13228 <returnvalue>t
</returnvalue>
13233 <entry role=
"func_table_entry"><para role=
"func_signature">
13234 <type>tsvector
</type> <literal>||
</literal> <type>tsvector
</type>
13235 <returnvalue>tsvector
</returnvalue>
13238 Concatenates two
<type>tsvector
</type>s. If both inputs contain
13239 lexeme positions, the second input's positions are adjusted
13243 <literal>'a:
1 b:
2'::tsvector || 'c:
1 d:
2 b:
3'::tsvector
</literal>
13244 <returnvalue>'a':
1 'b':
2,
5 'c':
3 'd':
4</returnvalue>
13249 <entry role=
"func_table_entry"><para role=
"func_signature">
13250 <type>tsquery
</type> <literal>&&</literal> <type>tsquery
</type>
13251 <returnvalue>tsquery
</returnvalue>
13254 ANDs two
<type>tsquery
</type>s together, producing a query that
13255 matches documents that match both input queries.
13258 <literal>'fat | rat'::tsquery
&& 'cat'::tsquery
</literal>
13259 <returnvalue>( 'fat' | 'rat' )
& 'cat'
</returnvalue>
13264 <entry role=
"func_table_entry"><para role=
"func_signature">
13265 <type>tsquery
</type> <literal>||
</literal> <type>tsquery
</type>
13266 <returnvalue>tsquery
</returnvalue>
13269 ORs two
<type>tsquery
</type>s together, producing a query that
13270 matches documents that match either input query.
13273 <literal>'fat | rat'::tsquery || 'cat'::tsquery
</literal>
13274 <returnvalue>'fat' | 'rat' | 'cat'
</returnvalue>
13279 <entry role=
"func_table_entry"><para role=
"func_signature">
13280 <literal>!!
</literal> <type>tsquery
</type>
13281 <returnvalue>tsquery
</returnvalue>
13284 Negates a
<type>tsquery
</type>, producing a query that matches
13285 documents that do not match the input query.
13288 <literal>!! 'cat'::tsquery
</literal>
13289 <returnvalue>!'cat'
</returnvalue>
13294 <entry role=
"func_table_entry"><para role=
"func_signature">
13295 <type>tsquery
</type> <literal><-
></literal> <type>tsquery
</type>
13296 <returnvalue>tsquery
</returnvalue>
13299 Constructs a phrase query, which matches if the two input queries
13300 match at successive lexemes.
13303 <literal>to_tsquery('fat')
<-
> to_tsquery('rat')
</literal>
13304 <returnvalue>'fat'
<-
> 'rat'
</returnvalue>
13309 <entry role=
"func_table_entry"><para role=
"func_signature">
13310 <type>tsquery
</type> <literal>@
></literal> <type>tsquery
</type>
13311 <returnvalue>boolean
</returnvalue>
13314 Does first
<type>tsquery
</type> contain the second? (This considers
13315 only whether all the lexemes appearing in one query appear in the
13316 other, ignoring the combining operators.)
13319 <literal>'cat'::tsquery @
> 'cat
& rat'::tsquery
</literal>
13320 <returnvalue>f
</returnvalue>
13325 <entry role=
"func_table_entry"><para role=
"func_signature">
13326 <type>tsquery
</type> <literal><@
</literal> <type>tsquery
</type>
13327 <returnvalue>boolean
</returnvalue>
13330 Is first
<type>tsquery
</type> contained in the second? (This
13331 considers only whether all the lexemes appearing in one query appear
13332 in the other, ignoring the combining operators.)
13335 <literal>'cat'::tsquery
<@ 'cat
& rat'::tsquery
</literal>
13336 <returnvalue>t
</returnvalue>
13339 <literal>'cat'::tsquery
<@ '!cat
& rat'::tsquery
</literal>
13340 <returnvalue>t
</returnvalue>
13348 In addition to these specialized operators, the usual comparison
13349 operators shown in
<xref linkend=
"functions-comparison-op-table"/> are
13350 available for types
<type>tsvector
</type> and
<type>tsquery
</type>.
13352 useful for text searching but allow, for example, unique indexes to be
13353 built on columns of these types.
13356 <table id=
"textsearch-functions-table">
13357 <title>Text Search Functions
</title>
13361 <entry role=
"func_table_entry"><para role=
"func_signature">
13375 <entry role=
"func_table_entry"><para role=
"func_signature">
13377 <primary>array_to_tsvector
</primary>
13379 <function>array_to_tsvector
</function> (
<type>text[]
</type> )
13380 <returnvalue>tsvector
</returnvalue>
13383 Converts an array of text strings to a
<type>tsvector
</type>.
13384 The given strings are used as lexemes as-is, without further
13385 processing. Array elements must not be empty strings
13386 or
<literal>NULL
</literal>.
13389 <literal>array_to_tsvector('{fat,cat,rat}'::text[])
</literal>
13390 <returnvalue>'cat' 'fat' 'rat'
</returnvalue>
13395 <entry role=
"func_table_entry"><para role=
"func_signature">
13397 <primary>get_current_ts_config
</primary>
13399 <function>get_current_ts_config
</function> ( )
13400 <returnvalue>regconfig
</returnvalue>
13403 Returns the OID of the current default text search configuration
13404 (as set by
<xref linkend=
"guc-default-text-search-config"/>).
13407 <literal>get_current_ts_config()
</literal>
13408 <returnvalue>english
</returnvalue>
13413 <entry role=
"func_table_entry"><para role=
"func_signature">
13415 <primary>length
</primary>
13417 <function>length
</function> (
<type>tsvector
</type> )
13418 <returnvalue>integer
</returnvalue>
13421 Returns the number of lexemes in the
<type>tsvector
</type>.
13424 <literal>length('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13425 <returnvalue>3</returnvalue>
13430 <entry role=
"func_table_entry"><para role=
"func_signature">
13432 <primary>numnode
</primary>
13434 <function>numnode
</function> (
<type>tsquery
</type> )
13435 <returnvalue>integer
</returnvalue>
13438 Returns the number of lexemes plus operators in
13439 the
<type>tsquery
</type>.
13442 <literal>numnode('(fat
& rat) | cat'::tsquery)
</literal>
13443 <returnvalue>5</returnvalue>
13448 <entry role=
"func_table_entry"><para role=
"func_signature">
13450 <primary>plainto_tsquery
</primary>
13452 <function>plainto_tsquery
</function> (
13453 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13454 <parameter>query
</parameter> <type>text
</type> )
13455 <returnvalue>tsquery
</returnvalue>
13458 Converts text to a
<type>tsquery
</type>, normalizing words according to
13459 the specified or default configuration. Any punctuation in the string
13460 is ignored (it does not determine query operators). The resulting
13461 query matches documents containing all non-stopwords in the text.
13464 <literal>plainto_tsquery('english', 'The Fat Rats')
</literal>
13465 <returnvalue>'fat'
& 'rat'
</returnvalue>
13470 <entry role=
"func_table_entry"><para role=
"func_signature">
13472 <primary>phraseto_tsquery
</primary>
13474 <function>phraseto_tsquery
</function> (
13475 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13476 <parameter>query
</parameter> <type>text
</type> )
13477 <returnvalue>tsquery
</returnvalue>
13480 Converts text to a
<type>tsquery
</type>, normalizing words according to
13481 the specified or default configuration. Any punctuation in the string
13482 is ignored (it does not determine query operators). The resulting
13483 query matches phrases containing all non-stopwords in the text.
13486 <literal>phraseto_tsquery('english', 'The Fat Rats')
</literal>
13487 <returnvalue>'fat'
<-
> 'rat'
</returnvalue>
13490 <literal>phraseto_tsquery('english', 'The Cat and Rats')
</literal>
13491 <returnvalue>'cat'
<2> 'rat'
</returnvalue>
13496 <entry role=
"func_table_entry"><para role=
"func_signature">
13498 <primary>websearch_to_tsquery
</primary>
13500 <function>websearch_to_tsquery
</function> (
13501 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13502 <parameter>query
</parameter> <type>text
</type> )
13503 <returnvalue>tsquery
</returnvalue>
13506 Converts text to a
<type>tsquery
</type>, normalizing words according
13507 to the specified or default configuration. Quoted word sequences are
13508 converted to phrase tests. The word
<quote>or
</quote> is understood
13509 as producing an OR operator, and a dash produces a NOT operator;
13510 other punctuation is ignored.
13511 This approximates the behavior of some common web search tools.
13514 <literal>websearch_to_tsquery('english', '
"fat rat" or cat dog')
</literal>
13515 <returnvalue>'fat'
<-
> 'rat' | 'cat'
& 'dog'
</returnvalue>
13520 <entry role=
"func_table_entry"><para role=
"func_signature">
13522 <primary>querytree
</primary>
13524 <function>querytree
</function> (
<type>tsquery
</type> )
13525 <returnvalue>text
</returnvalue>
13528 Produces a representation of the indexable portion of
13529 a
<type>tsquery
</type>. A result that is empty or
13530 just
<literal>T
</literal> indicates a non-indexable query.
13533 <literal>querytree('foo
& ! bar'::tsquery)
</literal>
13534 <returnvalue>'foo'
</returnvalue>
13539 <entry role=
"func_table_entry"><para role=
"func_signature">
13541 <primary>setweight
</primary>
13543 <function>setweight
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weight
</parameter> <type>"char"</type> )
13544 <returnvalue>tsvector
</returnvalue>
13547 Assigns the specified
<parameter>weight
</parameter> to each element
13548 of the
<parameter>vector
</parameter>.
13551 <literal>setweight('fat:
2,
4 cat:
3 rat:
5B'::tsvector, 'A')
</literal>
13552 <returnvalue>'cat':
3A 'fat':
2A,
4A 'rat':
5A
</returnvalue>
13557 <entry role=
"func_table_entry"><para role=
"func_signature">
13559 <primary>setweight
</primary>
13560 <secondary>setweight for specific lexeme(s)
</secondary>
13562 <function>setweight
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weight
</parameter> <type>"char"</type>,
<parameter>lexemes
</parameter> <type>text[]
</type> )
13563 <returnvalue>tsvector
</returnvalue>
13566 Assigns the specified
<parameter>weight
</parameter> to elements
13567 of the
<parameter>vector
</parameter> that are listed
13568 in
<parameter>lexemes
</parameter>.
13569 The strings in
<parameter>lexemes
</parameter> are taken as lexemes
13570 as-is, without further processing. Strings that do not match any
13571 lexeme in
<parameter>vector
</parameter> are ignored.
13574 <literal>setweight('fat:
2,
4 cat:
3 rat:
5,
6B'::tsvector, 'A', '{cat,rat}')
</literal>
13575 <returnvalue>'cat':
3A 'fat':
2,
4 'rat':
5A,
6A
</returnvalue>
13580 <entry role=
"func_table_entry"><para role=
"func_signature">
13582 <primary>strip
</primary>
13584 <function>strip
</function> (
<type>tsvector
</type> )
13585 <returnvalue>tsvector
</returnvalue>
13588 Removes positions and weights from the
<type>tsvector
</type>.
13591 <literal>strip('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13592 <returnvalue>'cat' 'fat' 'rat'
</returnvalue>
13597 <entry role=
"func_table_entry"><para role=
"func_signature">
13599 <primary>to_tsquery
</primary>
13601 <function>to_tsquery
</function> (
13602 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13603 <parameter>query
</parameter> <type>text
</type> )
13604 <returnvalue>tsquery
</returnvalue>
13607 Converts text to a
<type>tsquery
</type>, normalizing words according to
13608 the specified or default configuration. The words must be combined
13609 by valid
<type>tsquery
</type> operators.
13612 <literal>to_tsquery('english', 'The
& Fat
& Rats')
</literal>
13613 <returnvalue>'fat'
& 'rat'
</returnvalue>
13618 <entry role=
"func_table_entry"><para role=
"func_signature">
13620 <primary>to_tsvector
</primary>
13622 <function>to_tsvector
</function> (
13623 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13624 <parameter>document
</parameter> <type>text
</type> )
13625 <returnvalue>tsvector
</returnvalue>
13628 Converts text to a
<type>tsvector
</type>, normalizing words according
13629 to the specified or default configuration. Position information is
13630 included in the result.
13633 <literal>to_tsvector('english', 'The Fat Rats')
</literal>
13634 <returnvalue>'fat':
2 'rat':
3</returnvalue>
13639 <entry role=
"func_table_entry"><para role=
"func_signature">
13640 <function>to_tsvector
</function> (
13641 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13642 <parameter>document
</parameter> <type>json
</type> )
13643 <returnvalue>tsvector
</returnvalue>
13645 <para role=
"func_signature">
13646 <function>to_tsvector
</function> (
13647 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13648 <parameter>document
</parameter> <type>jsonb
</type> )
13649 <returnvalue>tsvector
</returnvalue>
13652 Converts each string value in the JSON document to
13653 a
<type>tsvector
</type>, normalizing words according to the specified
13654 or default configuration. The results are then concatenated in
13655 document order to produce the output. Position information is
13656 generated as though one stopword exists between each pair of string
13657 values. (Beware that
<quote>document order
</quote> of the fields of a
13658 JSON object is implementation-dependent when the input
13659 is
<type>jsonb
</type>; observe the difference in the examples.)
13662 <literal>to_tsvector('english', '{
"aa":
"The Fat Rats",
"b":
"dog"}'::json)
</literal>
13663 <returnvalue>'dog':
5 'fat':
2 'rat':
3</returnvalue>
13666 <literal>to_tsvector('english', '{
"aa":
"The Fat Rats",
"b":
"dog"}'::jsonb)
</literal>
13667 <returnvalue>'dog':
1 'fat':
4 'rat':
5</returnvalue>
13672 <entry role=
"func_table_entry"><para role=
"func_signature">
13674 <primary>json_to_tsvector
</primary>
13676 <function>json_to_tsvector
</function> (
13677 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13678 <parameter>document
</parameter> <type>json
</type>,
13679 <parameter>filter
</parameter> <type>jsonb
</type> )
13680 <returnvalue>tsvector
</returnvalue>
13682 <para role=
"func_signature">
13684 <primary>jsonb_to_tsvector
</primary>
13686 <function>jsonb_to_tsvector
</function> (
13687 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13688 <parameter>document
</parameter> <type>jsonb
</type>,
13689 <parameter>filter
</parameter> <type>jsonb
</type> )
13690 <returnvalue>tsvector
</returnvalue>
13693 Selects each item in the JSON document that is requested by
13694 the
<parameter>filter
</parameter> and converts each one to
13695 a
<type>tsvector
</type>, normalizing words according to the specified
13696 or default configuration. The results are then concatenated in
13697 document order to produce the output. Position information is
13698 generated as though one stopword exists between each pair of selected
13699 items. (Beware that
<quote>document order
</quote> of the fields of a
13700 JSON object is implementation-dependent when the input
13701 is
<type>jsonb
</type>.)
13702 The
<parameter>filter
</parameter> must be a
<type>jsonb
</type>
13703 array containing zero or more of these keywords:
13704 <literal>"string"</literal> (to include all string values),
13705 <literal>"numeric"</literal> (to include all numeric values),
13706 <literal>"boolean"</literal> (to include all boolean values),
13707 <literal>"key"</literal> (to include all keys), or
13708 <literal>"all"</literal> (to include all the above).
13709 As a special case, the
<parameter>filter
</parameter> can also be a
13710 simple JSON value that is one of these keywords.
13713 <literal>json_to_tsvector('english', '{
"a":
"The Fat Rats",
"b":
123}'::json, '[
"string",
"numeric"]')
</literal>
13714 <returnvalue>'
123':
5 'fat':
2 'rat':
3</returnvalue>
13717 <literal>json_to_tsvector('english', '{
"cat":
"The Fat Rats",
"dog":
123}'::json, '
"all"')
</literal>
13718 <returnvalue>'
123':
9 'cat':
1 'dog':
7 'fat':
4 'rat':
5</returnvalue>
13723 <entry role=
"func_table_entry"><para role=
"func_signature">
13725 <primary>ts_delete
</primary>
13727 <function>ts_delete
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>lexeme
</parameter> <type>text
</type> )
13728 <returnvalue>tsvector
</returnvalue>
13731 Removes any occurrence of the given
<parameter>lexeme
</parameter>
13732 from the
<parameter>vector
</parameter>.
13733 The
<parameter>lexeme
</parameter> string is treated as a lexeme as-is,
13734 without further processing.
13737 <literal>ts_delete('fat:
2,
4 cat:
3 rat:
5A'::tsvector, 'fat')
</literal>
13738 <returnvalue>'cat':
3 'rat':
5A
</returnvalue>
13743 <entry role=
"func_table_entry"><para role=
"func_signature">
13744 <function>ts_delete
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>lexemes
</parameter> <type>text[]
</type> )
13745 <returnvalue>tsvector
</returnvalue>
13748 Removes any occurrences of the lexemes
13749 in
<parameter>lexemes
</parameter>
13750 from the
<parameter>vector
</parameter>.
13751 The strings in
<parameter>lexemes
</parameter> are taken as lexemes
13752 as-is, without further processing. Strings that do not match any
13753 lexeme in
<parameter>vector
</parameter> are ignored.
13756 <literal>ts_delete('fat:
2,
4 cat:
3 rat:
5A'::tsvector, ARRAY['fat','rat'])
</literal>
13757 <returnvalue>'cat':
3</returnvalue>
13762 <entry role=
"func_table_entry"><para role=
"func_signature">
13764 <primary>ts_filter
</primary>
13766 <function>ts_filter
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weights
</parameter> <type>"char"[]
</type> )
13767 <returnvalue>tsvector
</returnvalue>
13770 Selects only elements with the given
<parameter>weights
</parameter>
13771 from the
<parameter>vector
</parameter>.
13774 <literal>ts_filter('fat:
2,
4 cat:
3b,
7c rat:
5A'::tsvector, '{a,b}')
</literal>
13775 <returnvalue>'cat':
3B 'rat':
5A
</returnvalue>
13780 <entry role=
"func_table_entry"><para role=
"func_signature">
13782 <primary>ts_headline
</primary>
13784 <function>ts_headline
</function> (
13785 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13786 <parameter>document
</parameter> <type>text
</type>,
13787 <parameter>query
</parameter> <type>tsquery
</type>
13788 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13789 <returnvalue>text
</returnvalue>
13792 Displays, in an abbreviated form, the match(es) for
13793 the
<parameter>query
</parameter> in
13794 the
<parameter>document
</parameter>, which must be raw text not
13795 a
<type>tsvector
</type>. Words in the document are normalized
13796 according to the specified or default configuration before matching to
13797 the query. Use of this function is discussed in
13798 <xref linkend=
"textsearch-headline"/>, which also describes the
13799 available
<parameter>options
</parameter>.
13802 <literal>ts_headline('The fat cat ate the rat.', 'cat')
</literal>
13803 <returnvalue>The fat
<b
>cat
</b
> ate the rat.
</returnvalue>
13808 <entry role=
"func_table_entry"><para role=
"func_signature">
13809 <function>ts_headline
</function> (
13810 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13811 <parameter>document
</parameter> <type>json
</type>,
13812 <parameter>query
</parameter> <type>tsquery
</type>
13813 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13814 <returnvalue>text
</returnvalue>
13816 <para role=
"func_signature">
13817 <function>ts_headline
</function> (
13818 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13819 <parameter>document
</parameter> <type>jsonb
</type>,
13820 <parameter>query
</parameter> <type>tsquery
</type>
13821 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13822 <returnvalue>text
</returnvalue>
13825 Displays, in an abbreviated form, match(es) for
13826 the
<parameter>query
</parameter> that occur in string values
13827 within the JSON
<parameter>document
</parameter>.
13828 See
<xref linkend=
"textsearch-headline"/> for more details.
13831 <literal>ts_headline('{
"cat":
"raining cats and dogs"}'::jsonb, 'cat')
</literal>
13832 <returnvalue>{
"cat":
"raining <b>cats</b> and dogs"}
</returnvalue>
13837 <entry role=
"func_table_entry"><para role=
"func_signature">
13839 <primary>ts_rank
</primary>
13841 <function>ts_rank
</function> (
13842 <optional> <parameter>weights
</parameter> <type>real[]
</type>,
</optional>
13843 <parameter>vector
</parameter> <type>tsvector
</type>,
13844 <parameter>query
</parameter> <type>tsquery
</type>
13845 <optional>,
<parameter>normalization
</parameter> <type>integer
</type> </optional> )
13846 <returnvalue>real
</returnvalue>
13849 Computes a score showing how well
13850 the
<parameter>vector
</parameter> matches
13851 the
<parameter>query
</parameter>. See
13852 <xref linkend=
"textsearch-ranking"/> for details.
13855 <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')
</literal>
13856 <returnvalue>0.06079271</returnvalue>
13861 <entry role=
"func_table_entry"><para role=
"func_signature">
13863 <primary>ts_rank_cd
</primary>
13865 <function>ts_rank_cd
</function> (
13866 <optional> <parameter>weights
</parameter> <type>real[]
</type>,
</optional>
13867 <parameter>vector
</parameter> <type>tsvector
</type>,
13868 <parameter>query
</parameter> <type>tsquery
</type>
13869 <optional>,
<parameter>normalization
</parameter> <type>integer
</type> </optional> )
13870 <returnvalue>real
</returnvalue>
13873 Computes a score showing how well
13874 the
<parameter>vector
</parameter> matches
13875 the
<parameter>query
</parameter>, using a cover density
13876 algorithm. See
<xref linkend=
"textsearch-ranking"/> for details.
13879 <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')
</literal>
13880 <returnvalue>0.1</returnvalue>
13885 <entry role=
"func_table_entry"><para role=
"func_signature">
13887 <primary>ts_rewrite
</primary>
13889 <function>ts_rewrite
</function> (
<parameter>query
</parameter> <type>tsquery
</type>,
13890 <parameter>target
</parameter> <type>tsquery
</type>,
13891 <parameter>substitute
</parameter> <type>tsquery
</type> )
13892 <returnvalue>tsquery
</returnvalue>
13895 Replaces occurrences of
<parameter>target
</parameter>
13896 with
<parameter>substitute
</parameter>
13897 within the
<parameter>query
</parameter>.
13898 See
<xref linkend=
"textsearch-query-rewriting"/> for details.
13901 <literal>ts_rewrite('a
& b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)
</literal>
13902 <returnvalue>'b'
& ( 'foo' | 'bar' )
</returnvalue>
13907 <entry role=
"func_table_entry"><para role=
"func_signature">
13908 <function>ts_rewrite
</function> (
<parameter>query
</parameter> <type>tsquery
</type>,
13909 <parameter>select
</parameter> <type>text
</type> )
13910 <returnvalue>tsquery
</returnvalue>
13913 Replaces portions of the
<parameter>query
</parameter> according to
13914 target(s) and substitute(s) obtained by executing
13915 a
<command>SELECT
</command> command.
13916 See
<xref linkend=
"textsearch-query-rewriting"/> for details.
13919 <literal>SELECT ts_rewrite('a
& b'::tsquery, 'SELECT t,s FROM aliases')
</literal>
13920 <returnvalue>'b'
& ( 'foo' | 'bar' )
</returnvalue>
13925 <entry role=
"func_table_entry"><para role=
"func_signature">
13927 <primary>tsquery_phrase
</primary>
13929 <function>tsquery_phrase
</function> (
<parameter>query1
</parameter> <type>tsquery
</type>,
<parameter>query2
</parameter> <type>tsquery
</type> )
13930 <returnvalue>tsquery
</returnvalue>
13933 Constructs a phrase query that searches
13934 for matches of
<parameter>query1
</parameter>
13935 and
<parameter>query2
</parameter> at successive lexemes (same
13936 as
<literal><-
></literal> operator).
13939 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))
</literal>
13940 <returnvalue>'fat'
<-
> 'cat'
</returnvalue>
13945 <entry role=
"func_table_entry"><para role=
"func_signature">
13946 <function>tsquery_phrase
</function> (
<parameter>query1
</parameter> <type>tsquery
</type>,
<parameter>query2
</parameter> <type>tsquery
</type>,
<parameter>distance
</parameter> <type>integer
</type> )
13947 <returnvalue>tsquery
</returnvalue>
13950 Constructs a phrase query that searches
13951 for matches of
<parameter>query1
</parameter> and
13952 <parameter>query2
</parameter> that occur exactly
13953 <parameter>distance
</parameter> lexemes apart.
13956 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'),
10)
</literal>
13957 <returnvalue>'fat'
<10> 'cat'
</returnvalue>
13962 <entry role=
"func_table_entry"><para role=
"func_signature">
13964 <primary>tsvector_to_array
</primary>
13966 <function>tsvector_to_array
</function> (
<type>tsvector
</type> )
13967 <returnvalue>text[]
</returnvalue>
13970 Converts a
<type>tsvector
</type> to an array of lexemes.
13973 <literal>tsvector_to_array('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13974 <returnvalue>{cat,fat,rat}
</returnvalue>
13979 <entry role=
"func_table_entry"><para role=
"func_signature">
13981 <primary>unnest
</primary>
13982 <secondary>for tsvector
</secondary>
13984 <function>unnest
</function> (
<type>tsvector
</type> )
13985 <returnvalue>setof record
</returnvalue>
13986 (
<parameter>lexeme
</parameter> <type>text
</type>,
13987 <parameter>positions
</parameter> <type>smallint[]
</type>,
13988 <parameter>weights
</parameter> <type>text
</type> )
13991 Expands a
<type>tsvector
</type> into a set of rows, one per lexeme.
13994 <literal>select * from unnest('cat:
3 fat:
2,
4 rat:
5A'::tsvector)
</literal>
13995 <returnvalue></returnvalue>
13997 lexeme | positions | weights
13998 --------+-----------+---------
14000 fat | {
2,
4} | {D,D}
14011 All the text search functions that accept an optional
<type>regconfig
</type>
14012 argument will use the configuration specified by
14013 <xref linkend=
"guc-default-text-search-config"/>
14014 when that argument is omitted.
14020 <xref linkend=
"textsearch-functions-debug-table"/>
14021 are listed separately because they are not usually used in everyday text
14022 searching operations. They are primarily helpful for development and
14023 debugging of new text search configurations.
14026 <table id=
"textsearch-functions-debug-table">
14027 <title>Text Search Debugging Functions
</title>
14031 <entry role=
"func_table_entry"><para role=
"func_signature">
14045 <entry role=
"func_table_entry"><para role=
"func_signature">
14047 <primary>ts_debug
</primary>
14049 <function>ts_debug
</function> (
14050 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
14051 <parameter>document
</parameter> <type>text
</type> )
14052 <returnvalue>setof record
</returnvalue>
14053 (
<parameter>alias
</parameter> <type>text
</type>,
14054 <parameter>description
</parameter> <type>text
</type>,
14055 <parameter>token
</parameter> <type>text
</type>,
14056 <parameter>dictionaries
</parameter> <type>regdictionary[]
</type>,
14057 <parameter>dictionary
</parameter> <type>regdictionary
</type>,
14058 <parameter>lexemes
</parameter> <type>text[]
</type> )
14061 Extracts and normalizes tokens from
14062 the
<parameter>document
</parameter> according to the specified or
14063 default text search configuration, and returns information about how
14064 each token was processed.
14065 See
<xref linkend=
"textsearch-configuration-testing"/> for details.
14068 <literal>ts_debug('english', 'The Brightest supernovaes')
</literal>
14069 <returnvalue>(asciiword,
"Word, all ASCII",The,{english_stem},english_stem,{}) ...
</returnvalue>
14074 <entry role=
"func_table_entry"><para role=
"func_signature">
14076 <primary>ts_lexize
</primary>
14078 <function>ts_lexize
</function> (
<parameter>dict
</parameter> <type>regdictionary
</type>,
<parameter>token
</parameter> <type>text
</type> )
14079 <returnvalue>text[]
</returnvalue>
14082 Returns an array of replacement lexemes if the input token is known to
14083 the dictionary, or an empty array if the token is known to the
14084 dictionary but it is a stop word, or NULL if it is not a known word.
14085 See
<xref linkend=
"textsearch-dictionary-testing"/> for details.
14088 <literal>ts_lexize('english_stem', 'stars')
</literal>
14089 <returnvalue>{star}
</returnvalue>
14094 <entry role=
"func_table_entry"><para role=
"func_signature">
14096 <primary>ts_parse
</primary>
14098 <function>ts_parse
</function> (
<parameter>parser_name
</parameter> <type>text
</type>,
14099 <parameter>document
</parameter> <type>text
</type> )
14100 <returnvalue>setof record
</returnvalue>
14101 (
<parameter>tokid
</parameter> <type>integer
</type>,
14102 <parameter>token
</parameter> <type>text
</type> )
14105 Extracts tokens from the
<parameter>document
</parameter> using the
14107 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14110 <literal>ts_parse('default', 'foo - bar')
</literal>
14111 <returnvalue>(
1,foo) ...
</returnvalue>
14116 <entry role=
"func_table_entry"><para role=
"func_signature">
14117 <function>ts_parse
</function> (
<parameter>parser_oid
</parameter> <type>oid
</type>,
14118 <parameter>document
</parameter> <type>text
</type> )
14119 <returnvalue>setof record
</returnvalue>
14120 (
<parameter>tokid
</parameter> <type>integer
</type>,
14121 <parameter>token
</parameter> <type>text
</type> )
14124 Extracts tokens from the
<parameter>document
</parameter> using a
14125 parser specified by OID.
14126 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14129 <literal>ts_parse(
3722, 'foo - bar')
</literal>
14130 <returnvalue>(
1,foo) ...
</returnvalue>
14135 <entry role=
"func_table_entry"><para role=
"func_signature">
14137 <primary>ts_token_type
</primary>
14139 <function>ts_token_type
</function> (
<parameter>parser_name
</parameter> <type>text
</type> )
14140 <returnvalue>setof record
</returnvalue>
14141 (
<parameter>tokid
</parameter> <type>integer
</type>,
14142 <parameter>alias
</parameter> <type>text
</type>,
14143 <parameter>description
</parameter> <type>text
</type> )
14146 Returns a table that describes each type of token the named parser can
14148 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14151 <literal>ts_token_type('default')
</literal>
14152 <returnvalue>(
1,asciiword,
"Word, all ASCII") ...
</returnvalue>
14157 <entry role=
"func_table_entry"><para role=
"func_signature">
14158 <function>ts_token_type
</function> (
<parameter>parser_oid
</parameter> <type>oid
</type> )
14159 <returnvalue>setof record
</returnvalue>
14160 (
<parameter>tokid
</parameter> <type>integer
</type>,
14161 <parameter>alias
</parameter> <type>text
</type>,
14162 <parameter>description
</parameter> <type>text
</type> )
14165 Returns a table that describes each type of token a parser specified
14166 by OID can recognize.
14167 See
<xref linkend=
"textsearch-parser-testing"/> for details.
14170 <literal>ts_token_type(
3722)
</literal>
14171 <returnvalue>(
1,asciiword,
"Word, all ASCII") ...
</returnvalue>
14176 <entry role=
"func_table_entry"><para role=
"func_signature">
14178 <primary>ts_stat
</primary>
14180 <function>ts_stat
</function> (
<parameter>sqlquery
</parameter> <type>text
</type>
14181 <optional>,
<parameter>weights
</parameter> <type>text
</type> </optional> )
14182 <returnvalue>setof record
</returnvalue>
14183 (
<parameter>word
</parameter> <type>text
</type>,
14184 <parameter>ndoc
</parameter> <type>integer
</type>,
14185 <parameter>nentry
</parameter> <type>integer
</type> )
14188 Executes the
<parameter>sqlquery
</parameter>, which must return a
14189 single
<type>tsvector
</type> column, and returns statistics about each
14190 distinct lexeme contained in the data.
14191 See
<xref linkend=
"textsearch-statistics"/> for details.
14194 <literal>ts_stat('SELECT vector FROM apod')
</literal>
14195 <returnvalue>(foo,
10,
15) ...
</returnvalue>
14204 <sect1 id=
"functions-uuid">
14205 <title>UUID Functions
</title>
14207 <indexterm zone=
"datatype-uuid">
14208 <primary>UUID
</primary>
14209 <secondary>generating
</secondary>
14213 <primary>gen_random_uuid
</primary>
14217 <primary>uuid_extract_timestamp
</primary>
14221 <primary>uuid_extract_version
</primary>
14225 <productname>PostgreSQL
</productname> includes one function to generate a UUID:
14227 <function>gen_random_uuid
</function> ()
<returnvalue>uuid
</returnvalue>
14229 This function returns a version
4 (random) UUID. This is the most commonly
14230 used type of UUID and is appropriate for most applications.
14234 The
<xref linkend=
"uuid-ossp"/> module provides additional functions that
14235 implement other standard algorithms for generating UUIDs.
14239 There are also functions to extract data from UUIDs:
14241 <function>uuid_extract_timestamp
</function> (uuid)
<returnvalue>timestamp with time zone
</returnvalue>
14243 This function extracts a
<type>timestamp with time zone
</type> from UUID
14244 version
1. For other versions, this function returns null. Note that the
14245 extracted timestamp is not necessarily exactly equal to the time the UUID
14246 was generated; this depends on the implementation that generated the UUID.
14251 <function>uuid_extract_version
</function> (uuid)
<returnvalue>smallint
</returnvalue>
14253 This function extracts the version from a UUID of the variant described by
14254 <ulink url=
"https://datatracker.ietf.org/doc/html/rfc4122">RFC
4122</ulink>. For
14255 other variants, this function returns null. For example, for a UUID
14256 generated by
<function>gen_random_uuid
</function>, this function will
14261 <productname>PostgreSQL
</productname> also provides the usual comparison
14262 operators shown in
<xref linkend=
"functions-comparison-op-table"/> for
14267 <sect1 id=
"functions-xml">
14269 <title>XML Functions
</title>
14272 <primary>XML Functions
</primary>
14276 The functions and function-like expressions described in this
14277 section operate on values of type
<type>xml
</type>. See
<xref
14278 linkend=
"datatype-xml"/> for information about the
<type>xml
</type>
14279 type. The function-like expressions
<function>xmlparse
</function>
14280 and
<function>xmlserialize
</function> for converting to and from
14281 type
<type>xml
</type> are documented there, not in this section.
14285 Use of most of these functions
14286 requires
<productname>PostgreSQL
</productname> to have been built
14287 with
<command>configure --with-libxml
</command>.
14290 <sect2 id=
"functions-producing-xml">
14291 <title>Producing XML Content
</title>
14294 A set of functions and function-like expressions is available for
14295 producing XML content from SQL data. As such, they are
14296 particularly suitable for formatting query results into XML
14297 documents for processing in client applications.
14300 <sect3 id=
"functions-producing-xml-xmltext">
14301 <title><literal>xmltext
</literal></title>
14304 <primary>xmltext
</primary>
14308 <function>xmltext
</function> (
<type>text
</type> )
<returnvalue>xml
</returnvalue>
14312 The function
<function>xmltext
</function> returns an XML value with a single
14313 text node containing the input argument as its content. Predefined entities
14314 like ampersand (
<literal><![CDATA[&]]
></literal>), left and right angle brackets
14315 (
<literal><![CDATA[<
>]]
></literal>), and quotation marks (
<literal><![CDATA[
""]]
></literal>)
14322 SELECT xmltext('< foo & bar
>');
14324 -------------------------
14325 < foo
& bar
>
14330 <sect3 id=
"functions-producing-xml-xmlcomment">
14331 <title><literal>xmlcomment
</literal></title>
14334 <primary>xmlcomment
</primary>
14338 <function>xmlcomment
</function> (
<type>text
</type> )
<returnvalue>xml
</returnvalue>
14342 The function
<function>xmlcomment
</function> creates an XML value
14343 containing an XML comment with the specified text as content.
14344 The text cannot contain
<quote><literal>--
</literal></quote> or end with a
14345 <quote><literal>-
</literal></quote>, otherwise the resulting construct
14346 would not be a valid XML comment.
14347 If the argument is null, the result is null.
14353 SELECT xmlcomment('hello');
14362 <sect3 id=
"functions-producing-xml-xmlconcat">
14363 <title><literal>xmlconcat
</literal></title>
14366 <primary>xmlconcat
</primary>
14370 <function>xmlconcat
</function> (
<type>xml
</type> <optional>, ...
</optional> )
<returnvalue>xml
</returnvalue>
14374 The function
<function>xmlconcat
</function> concatenates a list
14375 of individual XML values to create a single value containing an
14376 XML content fragment. Null values are omitted; the result is
14377 only null if there are no nonnull arguments.
14383 SELECT xmlconcat('
<abc/>', '
<bar>foo
</bar>');
14386 ----------------------
14387 <abc/><bar>foo
</bar>
14392 XML declarations, if present, are combined as follows. If all
14393 argument values have the same XML version declaration, that
14394 version is used in the result, else no version is used. If all
14395 argument values have the standalone declaration value
14396 <quote>yes
</quote>, then that value is used in the result. If
14397 all argument values have a standalone declaration value and at
14398 least one is
<quote>no
</quote>, then that is used in the result.
14399 Else the result will have no standalone declaration. If the
14400 result is determined to require a standalone declaration but no
14401 version declaration, a version declaration with version
1.0 will
14402 be used because XML requires an XML declaration to contain a
14403 version declaration. Encoding declarations are ignored and
14404 removed in all cases.
14410 SELECT xmlconcat('
<?xml version=
"1.1"?><foo/>', '
<?xml version=
"1.1" standalone=
"no"?><bar/>');
14413 -----------------------------------
14414 <?xml version=
"1.1"?><foo/><bar/>
14419 <sect3 id=
"functions-producing-xml-xmlelement">
14420 <title><literal>xmlelement
</literal></title>
14423 <primary>xmlelement
</primary>
14427 <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>
14431 The
<function>xmlelement
</function> expression produces an XML
14432 element with the given name, attributes, and content.
14433 The
<replaceable>name
</replaceable>
14434 and
<replaceable>attname
</replaceable> items shown in the syntax are
14435 simple identifiers, not values. The
<replaceable>attvalue
</replaceable>
14436 and
<replaceable>content
</replaceable> items are expressions, which can
14437 yield any
<productname>PostgreSQL
</productname> data type. The
14438 argument(s) within
<literal>XMLATTRIBUTES
</literal> generate attributes
14439 of the XML element; the
<replaceable>content
</replaceable> value(s) are
14440 concatenated to form its content.
14446 SELECT xmlelement(name foo);
14452 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
14458 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
14461 -------------------------------------
14462 <foo bar=
"2007-01-26">content
</foo>
14467 Element and attribute names that are not valid XML names are
14468 escaped by replacing the offending characters by the sequence
14469 <literal>_x
<replaceable>HHHH
</replaceable>_
</literal>, where
14470 <replaceable>HHHH
</replaceable> is the character's Unicode
14471 codepoint in hexadecimal notation. For example:
14473 SELECT xmlelement(name
"foo$bar", xmlattributes('xyz' as
"a&b"));
14476 ----------------------------------
14477 <foo_x0024_bar a_x0026_b=
"xyz"/>
14482 An explicit attribute name need not be specified if the attribute
14483 value is a column reference, in which case the column's name will
14484 be used as the attribute name by default. In other cases, the
14485 attribute must be given an explicit name. So this example is
14488 CREATE TABLE test (a xml, b xml);
14489 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
14493 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
14494 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
14499 Element content, if specified, will be formatted according to
14500 its data type. If the content is itself of type
<type>xml
</type>,
14501 complex XML documents can be constructed. For example:
14503 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
14504 xmlelement(name abc),
14505 xmlcomment('test'),
14506 xmlelement(name xyz));
14509 ----------------------------------------------
14510 <foo bar=
"xyz"><abc/><!--test--><xyz/></foo>
14513 Content of other types will be formatted into valid XML character
14514 data. This means in particular that the characters
<,
>,
14515 and
& will be converted to entities. Binary data (data type
14516 <type>bytea
</type>) will be represented in base64 or hex
14517 encoding, depending on the setting of the configuration parameter
14518 <xref linkend=
"guc-xmlbinary"/>. The particular behavior for
14519 individual data types is expected to evolve in order to align the
14520 PostgreSQL mappings with those specified in SQL:
2006 and later,
14521 as discussed in
<xref linkend=
"functions-xml-limits-casts"/>.
14525 <sect3 id=
"functions-producing-xml-xmlforest">
14526 <title><literal>xmlforest
</literal></title>
14529 <primary>xmlforest
</primary>
14533 <function>xmlforest
</function> (
<replaceable>content
</replaceable> <optional> <literal>AS
</literal> <replaceable>name
</replaceable> </optional> <optional>, ...
</optional> )
<returnvalue>xml
</returnvalue>
14537 The
<function>xmlforest
</function> expression produces an XML
14538 forest (sequence) of elements using the given names and content.
14539 As for
<function>xmlelement
</function>,
14540 each
<replaceable>name
</replaceable> must be a simple identifier, while
14541 the
<replaceable>content
</replaceable> expressions can have any data
14548 SELECT xmlforest('abc' AS foo,
123 AS bar);
14551 ------------------------------
14552 <foo
>abc
</foo
><bar
>123</bar
>
14555 SELECT xmlforest(table_name, column_name)
14556 FROM information_schema.columns
14557 WHERE table_schema = 'pg_catalog';
14560 ------------------------------------
&zwsp;-----------------------------------
14561 <table_name
>pg_authid
</table_name
>&zwsp;<column_name
>rolname
</column_name
>
14562 <table_name
>pg_authid
</table_name
>&zwsp;<column_name
>rolsuper
</column_name
>
14566 As seen in the second example, the element name can be omitted if
14567 the content value is a column reference, in which case the column
14568 name is used by default. Otherwise, a name must be specified.
14572 Element names that are not valid XML names are escaped as shown
14573 for
<function>xmlelement
</function> above. Similarly, content
14574 data is escaped to make valid XML content, unless it is already
14575 of type
<type>xml
</type>.
14579 Note that XML forests are not valid XML documents if they consist
14580 of more than one element, so it might be useful to wrap
14581 <function>xmlforest
</function> expressions in
14582 <function>xmlelement
</function>.
14586 <sect3 id=
"functions-producing-xml-xmlpi">
14587 <title><literal>xmlpi
</literal></title>
14590 <primary>xmlpi
</primary>
14594 <function>xmlpi
</function> (
<literal>NAME
</literal> <replaceable>name
</replaceable> <optional>,
<replaceable>content
</replaceable> </optional> )
<returnvalue>xml
</returnvalue>
14598 The
<function>xmlpi
</function> expression creates an XML
14599 processing instruction.
14600 As for
<function>xmlelement
</function>,
14601 the
<replaceable>name
</replaceable> must be a simple identifier, while
14602 the
<replaceable>content
</replaceable> expression can have any data type.
14603 The
<replaceable>content
</replaceable>, if present, must not contain the
14604 character sequence
<literal>?
></literal>.
14610 SELECT xmlpi(name php, 'echo
"hello world";');
14613 -----------------------------
14614 <?php echo
"hello world";
?>
14619 <sect3 id=
"functions-producing-xml-xmlroot">
14620 <title><literal>xmlroot
</literal></title>
14623 <primary>xmlroot
</primary>
14627 <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>
14631 The
<function>xmlroot
</function> expression alters the properties
14632 of the root node of an XML value. If a version is specified,
14633 it replaces the value in the root node's version declaration; if a
14634 standalone setting is specified, it replaces the value in the
14635 root node's standalone declaration.
14640 SELECT xmlroot(xmlparse(document '
<?xml version=
"1.1"?><content>abc
</content>'),
14641 version '
1.0', standalone yes);
14644 ----------------------------------------
14645 <?xml version=
"1.0" standalone=
"yes"?>
14646 <content>abc
</content>
14651 <sect3 id=
"functions-xml-xmlagg">
14652 <title><literal>xmlagg
</literal></title>
14655 <primary>xmlagg
</primary>
14659 <function>xmlagg
</function> (
<type>xml
</type> )
<returnvalue>xml
</returnvalue>
14663 The function
<function>xmlagg
</function> is, unlike the other
14664 functions described here, an aggregate function. It concatenates the
14665 input values to the aggregate function call,
14666 much like
<function>xmlconcat
</function> does, except that concatenation
14667 occurs across rows rather than across expressions in a single row.
14668 See
<xref linkend=
"functions-aggregate"/> for additional information
14669 about aggregate functions.
14675 CREATE TABLE test (y int, x xml);
14676 INSERT INTO test VALUES (
1, '
<foo>abc
</foo>');
14677 INSERT INTO test VALUES (
2, '
<bar/>');
14678 SELECT xmlagg(x) FROM test;
14680 ----------------------
14681 <foo>abc
</foo><bar/>
14686 To determine the order of the concatenation, an
<literal>ORDER BY
</literal>
14687 clause may be added to the aggregate call as described in
14688 <xref linkend=
"syntax-aggregates"/>. For example:
14691 SELECT xmlagg(x ORDER BY y DESC) FROM test;
14693 ----------------------
14694 <bar/><foo>abc
</foo>
14699 The following non-standard approach used to be recommended
14700 in previous versions, and may still be useful in specific
14704 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
14706 ----------------------
14707 <bar/><foo>abc
</foo>
14713 <sect2 id=
"functions-xml-predicates">
14714 <title>XML Predicates
</title>
14717 The expressions described in this section check properties
14718 of
<type>xml
</type> values.
14721 <sect3 id=
"functions-producing-xml-is-document">
14722 <title><literal>IS DOCUMENT
</literal></title>
14725 <primary>IS DOCUMENT
</primary>
14729 <type>xml
</type> <literal>IS DOCUMENT
</literal> <returnvalue>boolean
</returnvalue>
14733 The expression
<literal>IS DOCUMENT
</literal> returns true if the
14734 argument XML value is a proper XML document, false if it is not
14735 (that is, it is a content fragment), or null if the argument is
14736 null. See
<xref linkend=
"datatype-xml"/> about the difference
14737 between documents and content fragments.
14741 <sect3 id=
"functions-producing-xml-is-not-document">
14742 <title><literal>IS NOT DOCUMENT
</literal></title>
14745 <primary>IS NOT DOCUMENT
</primary>
14749 <type>xml
</type> <literal>IS NOT DOCUMENT
</literal> <returnvalue>boolean
</returnvalue>
14753 The expression
<literal>IS NOT DOCUMENT
</literal> returns false if the
14754 argument XML value is a proper XML document, true if it is not (that is,
14755 it is a content fragment), or null if the argument is null.
14759 <sect3 id=
"xml-exists">
14760 <title><literal>XMLEXISTS
</literal></title>
14763 <primary>XMLEXISTS
</primary>
14767 <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>
14771 The function
<function>xmlexists
</function> evaluates an XPath
1.0
14772 expression (the first argument), with the passed XML value as its context
14773 item. The function returns false if the result of that evaluation
14774 yields an empty node-set, true if it yields any other value. The
14775 function returns null if any argument is null. A nonnull value
14776 passed as the context item must be an XML document, not a content
14777 fragment or any non-XML value.
14783 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '
<towns><town>Toronto
</town><town>Ottawa
</town></towns>');
14793 The
<literal>BY REF
</literal> and
<literal>BY VALUE
</literal> clauses
14794 are accepted in
<productname>PostgreSQL
</productname>, but are ignored,
14795 as discussed in
<xref linkend=
"functions-xml-limits-postgresql"/>.
14799 In the SQL standard, the
<function>xmlexists
</function> function
14800 evaluates an expression in the XML Query language,
14801 but
<productname>PostgreSQL
</productname> allows only an XPath
1.0
14802 expression, as discussed in
14803 <xref linkend=
"functions-xml-limits-xpath1"/>.
14807 <sect3 id=
"xml-is-well-formed">
14808 <title><literal>xml_is_well_formed
</literal></title>
14811 <primary>xml_is_well_formed
</primary>
14815 <primary>xml_is_well_formed_document
</primary>
14819 <primary>xml_is_well_formed_content
</primary>
14823 <function>xml_is_well_formed
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14824 <function>xml_is_well_formed_document
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14825 <function>xml_is_well_formed_content
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14829 These functions check whether a
<type>text
</type> string represents
14830 well-formed XML, returning a Boolean result.
14831 <function>xml_is_well_formed_document
</function> checks for a well-formed
14832 document, while
<function>xml_is_well_formed_content
</function> checks
14833 for well-formed content.
<function>xml_is_well_formed
</function> does
14834 the former if the
<xref linkend=
"guc-xmloption"/> configuration
14835 parameter is set to
<literal>DOCUMENT
</literal>, or the latter if it is set to
14836 <literal>CONTENT
</literal>. This means that
14837 <function>xml_is_well_formed
</function> is useful for seeing whether
14838 a simple cast to type
<type>xml
</type> will succeed, whereas the other two
14839 functions are useful for seeing whether the corresponding variants of
14840 <function>XMLPARSE
</function> will succeed.
14847 SET xmloption TO DOCUMENT;
14848 SELECT xml_is_well_formed('<
>');
14850 --------------------
14854 SELECT xml_is_well_formed('
<abc/>');
14856 --------------------
14860 SET xmloption TO CONTENT;
14861 SELECT xml_is_well_formed('abc');
14863 --------------------
14867 SELECT xml_is_well_formed_document('
<pg:foo xmlns:
pg=
"http://postgresql.org/stuff">bar
</pg:foo>');
14868 xml_is_well_formed_document
14869 -----------------------------
14873 SELECT xml_is_well_formed_document('
<pg:foo xmlns:
pg=
"http://postgresql.org/stuff">bar
</my:foo>');
14874 xml_is_well_formed_document
14875 -----------------------------
14880 The last example shows that the checks include whether
14881 namespaces are correctly matched.
14886 <sect2 id=
"functions-xml-processing">
14887 <title>Processing XML
</title>
14890 To process values of data type
<type>xml
</type>, PostgreSQL offers
14891 the functions
<function>xpath
</function> and
14892 <function>xpath_exists
</function>, which evaluate XPath
1.0
14893 expressions, and the
<function>XMLTABLE
</function>
14897 <sect3 id=
"functions-xml-processing-xpath">
14898 <title><literal>xpath
</literal></title>
14901 <primary>XPath
</primary>
14905 <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>
14909 The function
<function>xpath
</function> evaluates the XPath
1.0
14910 expression
<parameter>xpath
</parameter> (given as text)
14911 against the XML value
14912 <parameter>xml
</parameter>. It returns an array of XML values
14913 corresponding to the node-set produced by the XPath expression.
14914 If the XPath expression returns a scalar value rather than a node-set,
14915 a single-element array is returned.
14919 The second argument must be a well formed XML document. In particular,
14920 it must have a single root node element.
14924 The optional third argument of the function is an array of namespace
14925 mappings. This array should be a two-dimensional
<type>text
</type> array with
14926 the length of the second axis being equal to
2 (i.e., it should be an
14927 array of arrays, each of which consists of exactly
2 elements).
14928 The first element of each array entry is the namespace name (alias), the
14929 second the namespace URI. It is not required that aliases provided in
14930 this array be the same as those being used in the XML document itself (in
14931 other words, both in the XML document and in the
<function>xpath
</function>
14932 function context, aliases are
<emphasis>local
</emphasis>).
14938 SELECT xpath('/my:a/text()', '
<my:a xmlns:
my=
"http://example.com">test
</my:a>',
14939 ARRAY[ARRAY['my', 'http://example.com']]);
14949 To deal with default (anonymous) namespaces, do something like this:
14951 SELECT xpath('//mydefns:b/text()', '
<a xmlns=
"http://example.com"><b>test
</b></a>',
14952 ARRAY[ARRAY['mydefns', 'http://example.com']]);
14962 <sect3 id=
"functions-xml-processing-xpath-exists">
14963 <title><literal>xpath_exists
</literal></title>
14966 <primary>xpath_exists
</primary>
14970 <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>
14974 The function
<function>xpath_exists
</function> is a specialized form
14975 of the
<function>xpath
</function> function. Instead of returning the
14976 individual XML values that satisfy the XPath
1.0 expression, this function
14977 returns a Boolean indicating whether the query was satisfied or not
14978 (specifically, whether it produced any value other than an empty node-set).
14979 This function is equivalent to the
<literal>XMLEXISTS
</literal> predicate,
14980 except that it also offers support for a namespace mapping argument.
14986 SELECT xpath_exists('/my:a/text()', '
<my:a xmlns:
my=
"http://example.com">test
</my:a>',
14987 ARRAY[ARRAY['my', 'http://example.com']]);
14997 <sect3 id=
"functions-xml-processing-xmltable">
14998 <title><literal>xmltable
</literal></title>
15001 <primary>xmltable
</primary>
15004 <indexterm zone=
"functions-xml-processing-xmltable">
15005 <primary>table function
</primary>
15006 <secondary>XMLTABLE
</secondary>
15010 <function>XMLTABLE
</function> (
15011 <optional> <literal>XMLNAMESPACES
</literal> (
<replaceable>namespace_uri
</replaceable> <literal>AS
</literal> <replaceable>namespace_name
</replaceable> <optional>, ...
</optional> ),
</optional>
15012 <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>
15013 <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>
15014 |
<literal>FOR ORDINALITY
</literal> }
15015 <optional>, ...
</optional>
15016 )
<returnvalue>setof record
</returnvalue>
15020 The
<function>xmltable
</function> expression produces a table based
15021 on an XML value, an XPath filter to extract rows, and a
15022 set of column definitions.
15023 Although it syntactically resembles a function, it can only appear
15024 as a table in a query's
<literal>FROM
</literal> clause.
15028 The optional
<literal>XMLNAMESPACES
</literal> clause gives a
15029 comma-separated list of namespace definitions, where
15030 each
<replaceable>namespace_uri
</replaceable> is a
<type>text
</type>
15031 expression and each
<replaceable>namespace_name
</replaceable> is a simple
15032 identifier. It specifies the XML namespaces used in the document and
15033 their aliases. A default namespace specification is not currently
15038 The required
<replaceable>row_expression
</replaceable> argument is an
15039 XPath
1.0 expression (given as
<type>text
</type>) that is evaluated,
15040 passing the XML value
<replaceable>document_expression
</replaceable> as
15041 its context item, to obtain a set of XML nodes. These nodes are what
15042 <function>xmltable
</function> transforms into output rows. No rows
15043 will be produced if the
<replaceable>document_expression
</replaceable>
15044 is null, nor if the
<replaceable>row_expression
</replaceable> produces
15045 an empty node-set or any value other than a node-set.
15049 <replaceable>document_expression
</replaceable> provides the context
15050 item for the
<replaceable>row_expression
</replaceable>. It must be a
15051 well-formed XML document; fragments/forests are not accepted.
15052 The
<literal>BY REF
</literal> and
<literal>BY VALUE
</literal> clauses
15053 are accepted but ignored, as discussed in
15054 <xref linkend=
"functions-xml-limits-postgresql"/>.
15058 In the SQL standard, the
<function>xmltable
</function> function
15059 evaluates expressions in the XML Query language,
15060 but
<productname>PostgreSQL
</productname> allows only XPath
1.0
15061 expressions, as discussed in
15062 <xref linkend=
"functions-xml-limits-xpath1"/>.
15066 The required
<literal>COLUMNS
</literal> clause specifies the
15067 column(s) that will be produced in the output table.
15068 See the syntax summary above for the format.
15069 A name is required for each column, as is a data type
15070 (unless
<literal>FOR ORDINALITY
</literal> is specified, in which case
15071 type
<type>integer
</type> is implicit). The path, default and
15072 nullability clauses are optional.
15076 A column marked
<literal>FOR ORDINALITY
</literal> will be populated
15077 with row numbers, starting with
1, in the order of nodes retrieved from
15078 the
<replaceable>row_expression
</replaceable>'s result node-set.
15079 At most one column may be marked
<literal>FOR ORDINALITY
</literal>.
15084 XPath
1.0 does not specify an order for nodes in a node-set, so code
15085 that relies on a particular order of the results will be
15086 implementation-dependent. Details can be found in
15087 <xref linkend=
"xml-xpath-1-specifics"/>.
15092 The
<replaceable>column_expression
</replaceable> for a column is an
15093 XPath
1.0 expression that is evaluated for each row, with the current
15094 node from the
<replaceable>row_expression
</replaceable> result as its
15095 context item, to find the value of the column. If
15096 no
<replaceable>column_expression
</replaceable> is given, then the
15097 column name is used as an implicit path.
15101 If a column's XPath expression returns a non-XML value (which is limited
15102 to string, boolean, or double in XPath
1.0) and the column has a
15103 PostgreSQL type other than
<type>xml
</type>, the column will be set
15104 as if by assigning the value's string representation to the PostgreSQL
15105 type. (If the value is a boolean, its string representation is taken
15106 to be
<literal>1</literal> or
<literal>0</literal> if the output
15107 column's type category is numeric, otherwise
<literal>true
</literal> or
15108 <literal>false
</literal>.)
15112 If a column's XPath expression returns a non-empty set of XML nodes
15113 and the column's PostgreSQL type is
<type>xml
</type>, the column will
15114 be assigned the expression result exactly, if it is of document or
15118 A result containing more than one element node at the top level, or
15119 non-whitespace text outside of an element, is an example of content form.
15120 An XPath result can be of neither form, for example if it returns an
15121 attribute node selected from the element that contains it. Such a result
15122 will be put into content form with each such disallowed node replaced by
15123 its string value, as defined for the XPath
1.0
15124 <function>string
</function> function.
15130 A non-XML result assigned to an
<type>xml
</type> output column produces
15131 content, a single text node with the string value of the result.
15132 An XML result assigned to a column of any other type may not have more than
15133 one node, or an error is raised. If there is exactly one node, the column
15134 will be set as if by assigning the node's string
15135 value (as defined for the XPath
1.0 <function>string
</function> function)
15136 to the PostgreSQL type.
15140 The string value of an XML element is the concatenation, in document order,
15141 of all text nodes contained in that element and its descendants. The string
15142 value of an element with no descendant text nodes is an
15143 empty string (not
<literal>NULL
</literal>).
15144 Any
<literal>xsi:nil
</literal> attributes are ignored.
15145 Note that the whitespace-only
<literal>text()
</literal> node between two non-text
15146 elements is preserved, and that leading whitespace on a
<literal>text()
</literal>
15147 node is not flattened.
15148 The XPath
1.0 <function>string
</function> function may be consulted for the
15149 rules defining the string value of other XML node types and non-XML values.
15153 The conversion rules presented here are not exactly those of the SQL
15154 standard, as discussed in
<xref linkend=
"functions-xml-limits-casts"/>.
15158 If the path expression returns an empty node-set
15159 (typically, when it does not match)
15160 for a given row, the column will be set to
<literal>NULL
</literal>, unless
15161 a
<replaceable>default_expression
</replaceable> is specified; then the
15162 value resulting from evaluating that expression is used.
15166 A
<replaceable>default_expression
</replaceable>, rather than being
15167 evaluated immediately when
<function>xmltable
</function> is called,
15168 is evaluated each time a default is needed for the column.
15169 If the expression qualifies as stable or immutable, the repeat
15170 evaluation may be skipped.
15171 This means that you can usefully use volatile functions like
15172 <function>nextval
</function> in
15173 <replaceable>default_expression
</replaceable>.
15177 Columns may be marked
<literal>NOT NULL
</literal>. If the
15178 <replaceable>column_expression
</replaceable> for a
<literal>NOT
15179 NULL
</literal> column does not match anything and there is
15180 no
<literal>DEFAULT
</literal> or
15181 the
<replaceable>default_expression
</replaceable> also evaluates to null,
15182 an error is reported.
15188 CREATE TABLE xmldata AS SELECT
15192 <COUNTRY_ID>AU
</COUNTRY_ID>
15193 <COUNTRY_NAME>Australia
</COUNTRY_NAME>
15196 <COUNTRY_ID>JP
</COUNTRY_ID>
15197 <COUNTRY_NAME>Japan
</COUNTRY_NAME>
15198 <PREMIER_NAME>Shinzo Abe
</PREMIER_NAME>
15199 <SIZE unit=
"sq_mi">145935</SIZE>
15202 <COUNTRY_ID>SG
</COUNTRY_ID>
15203 <COUNTRY_NAME>Singapore
</COUNTRY_NAME>
15204 <SIZE unit=
"sq_km">697</SIZE>
15211 XMLTABLE('//ROWS/ROW'
15213 COLUMNS id int PATH '@id',
15214 ordinality FOR ORDINALITY,
15215 "COUNTRY_NAME" text,
15216 country_id text PATH 'COUNTRY_ID',
15217 size_sq_km float PATH 'SIZE[@unit =
"sq_km"]',
15218 size_other text PATH
15219 'concat(SIZE[@unit!=
"sq_km"],
" ", SIZE[@unit!=
"sq_km"]/@unit)',
15220 premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified');
15222 id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
15223 ----+------------+--------------+------------+------------+--------------+---------------
15224 1 |
1 | Australia | AU | | | not specified
15225 5 |
2 | Japan | JP | |
145935 sq_mi | Shinzo Abe
15226 6 |
3 | Singapore | SG |
697 | | not specified
15229 The following example shows concatenation of multiple text() nodes,
15230 usage of the column name as XPath filter, and the treatment of whitespace,
15231 XML comments and processing instructions:
15234 CREATE TABLE xmlelements AS SELECT
15237 <element> Hello
<!-- xyxxz -->2a2
<?aaaaa?> <!--x--> bbb
<x>xxx
</x>CC
</element>
15242 FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
15244 -------------------------
15250 The following example illustrates how
15251 the
<literal>XMLNAMESPACES
</literal> clause can be used to specify
15252 a list of namespaces
15253 used in the XML document as well as in the XPath expressions:
15256 WITH xmldata(data) AS (VALUES ('
15257 <example xmlns=
"http://example.com/myns" xmlns:
B=
"http://example.com/b">
15258 <item foo=
"1" B:
bar=
"2"/>
15259 <item foo=
"3" B:
bar=
"4"/>
15260 <item foo=
"4" B:
bar=
"5"/>
15264 FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
15265 'http://example.com/b' AS
"B"),
15266 '/x:example/x:item'
15267 PASSING (SELECT data FROM xmldata)
15268 COLUMNS foo int PATH '@foo',
15269 bar int PATH '@B:bar');
15281 <sect2 id=
"functions-xml-mapping">
15282 <title>Mapping Tables to XML
</title>
15284 <indexterm zone=
"functions-xml-mapping">
15285 <primary>XML export
</primary>
15289 The following functions map the contents of relational tables to
15290 XML values. They can be thought of as XML export functionality:
15292 <function>table_to_xml
</function> (
<parameter>table
</parameter> <type>regclass
</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>query_to_xml
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15295 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15296 <function>cursor_to_xml
</function> (
<parameter>cursor
</parameter> <type>refcursor
</type>,
<parameter>count
</parameter> <type>integer
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15297 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15302 <function>table_to_xml
</function> maps the content of the named
15303 table, passed as parameter
<parameter>table
</parameter>. The
15304 <type>regclass
</type> type accepts strings identifying tables using the
15305 usual notation, including optional schema qualification and
15306 double quotes (see
<xref linkend=
"datatype-oid"/> for details).
15307 <function>query_to_xml
</function> executes the
15308 query whose text is passed as parameter
15309 <parameter>query
</parameter> and maps the result set.
15310 <function>cursor_to_xml
</function> fetches the indicated number of
15311 rows from the cursor specified by the parameter
15312 <parameter>cursor
</parameter>. This variant is recommended if
15313 large tables have to be mapped, because the result value is built
15314 up in memory by each function.
15318 If
<parameter>tableforest
</parameter> is false, then the resulting
15319 XML document looks like this:
15323 <columnname1>data
</columnname1>
15324 <columnname2>data
</columnname2>
15335 If
<parameter>tableforest
</parameter> is true, the result is an
15336 XML content fragment that looks like this:
15339 <columnname1>data
</columnname1>
15340 <columnname2>data
</columnname2>
15350 If no table name is available, that is, when mapping a query or a
15351 cursor, the string
<literal>table
</literal> is used in the first
15352 format,
<literal>row
</literal> in the second format.
15356 The choice between these formats is up to the user. The first
15357 format is a proper XML document, which will be important in many
15358 applications. The second format tends to be more useful in the
15359 <function>cursor_to_xml
</function> function if the result values are to be
15360 reassembled into one document later on. The functions for
15361 producing XML content discussed above, in particular
15362 <function>xmlelement
</function>, can be used to alter the results
15367 The data values are mapped in the same way as described for the
15368 function
<function>xmlelement
</function> above.
15372 The parameter
<parameter>nulls
</parameter> determines whether null
15373 values should be included in the output. If true, null values in
15374 columns are represented as:
15376 <columnname xsi:
nil=
"true"/>
15378 where
<literal>xsi
</literal> is the XML namespace prefix for XML
15379 Schema Instance. An appropriate namespace declaration will be
15380 added to the result value. If false, columns containing null
15381 values are simply omitted from the output.
15385 The parameter
<parameter>targetns
</parameter> specifies the
15386 desired XML namespace of the result. If no particular namespace
15387 is wanted, an empty string should be passed.
15391 The following functions return XML Schema documents describing the
15392 mappings performed by the corresponding functions above:
15394 <function>table_to_xmlschema
</function> (
<parameter>table
</parameter> <type>regclass
</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>query_to_xmlschema
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15397 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15398 <function>cursor_to_xmlschema
</function> (
<parameter>cursor
</parameter> <type>refcursor
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15399 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15401 It is essential that the same parameters are passed in order to
15402 obtain matching XML data mappings and XML Schema documents.
15406 The following functions produce XML data mappings and the
15407 corresponding XML Schema in one document (or forest), linked
15408 together. They can be useful where self-contained and
15409 self-describing results are wanted:
15411 <function>table_to_xml_and_xmlschema
</function> (
<parameter>table
</parameter> <type>regclass
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15412 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15413 <function>query_to_xml_and_xmlschema
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15414 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15419 In addition, the following functions are available to produce
15420 analogous mappings of entire schemas or the entire current
15423 <function>schema_to_xml
</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_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>
15427 <function>schema_to_xml_and_xmlschema
</function> (
<parameter>schema
</parameter> <type>name
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15428 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15430 <function>database_to_xml
</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_xmlschema
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15433 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15434 <function>database_to_xml_and_xmlschema
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15435 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15438 These functions ignore tables that are not readable by the current user.
15439 The database-wide functions additionally ignore schemas that the current
15440 user does not have
<literal>USAGE
</literal> (lookup) privilege for.
15444 Note that these potentially produce a lot of data, which needs to
15445 be built up in memory. When requesting content mappings of large
15446 schemas or databases, it might be worthwhile to consider mapping the
15447 tables separately instead, possibly even through a cursor.
15451 The result of a schema content mapping looks like this:
15462 </schemaname>]]
></screen>
15464 where the format of a table mapping depends on the
15465 <parameter>tableforest
</parameter> parameter as explained above.
15469 The result of a database content mapping looks like this:
15484 </dbname>]]
></screen>
15486 where the schema mapping is as above.
15490 As an example of using the output produced by these functions,
15491 <xref linkend=
"xslt-xml-html"/> shows an XSLT stylesheet that
15492 converts the output of
15493 <function>table_to_xml_and_xmlschema
</function> to an HTML
15494 document containing a tabular rendition of the table data. In a
15495 similar manner, the results from these functions can be
15496 converted into other XML-based formats.
15499 <example id=
"xslt-xml-html">
15500 <title>XSLT Stylesheet for Converting SQL/XML Output to HTML
</title>
15501 <programlisting><![CDATA[
15502 <?xml version=
"1.0"?>
15503 <xsl:stylesheet version=
"1.0"
15504 xmlns:
xsl=
"http://www.w3.org/1999/XSL/Transform"
15505 xmlns:
xsd=
"http://www.w3.org/2001/XMLSchema"
15506 xmlns=
"http://www.w3.org/1999/xhtml"
15509 <xsl:output method=
"xml"
15510 doctype-system=
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
15511 doctype-public=
"-//W3C/DTD XHTML 1.0 Strict//EN"
15514 <xsl:template match=
"/*">
15515 <xsl:variable name=
"schema" select=
"//xsd:schema"/>
15516 <xsl:variable name=
"tabletypename"
15517 select=
"$schema/xsd:element[@name=name(current())]/@type"/>
15518 <xsl:variable name=
"rowtypename"
15519 select=
"$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
15523 <title><xsl:value-of select=
"name(current())"/></title>
15528 <xsl:for-each select=
"$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
15529 <th><xsl:value-of select=
"."/></th>
15533 <xsl:for-each select=
"row">
15535 <xsl:for-each select=
"*">
15536 <td><xsl:value-of select=
"."/></td>
15546 ]]
></programlisting>
15551 <sect1 id=
"functions-json">
15552 <title>JSON Functions and Operators
</title>
15554 <indexterm zone=
"functions-json">
15555 <primary>JSON
</primary>
15556 <secondary>functions and operators
</secondary>
15558 <indexterm zone=
"functions-json">
15559 <primary>SQL/JSON
</primary>
15560 <secondary>functions and expressions
</secondary>
15564 This section describes:
15569 functions and operators for processing and creating JSON data
15574 the SQL/JSON path language
15579 the SQL/JSON query functions
15586 To provide native support for JSON data types within the SQL environment,
15587 <productname>PostgreSQL
</productname> implements the
15588 <firstterm>SQL/JSON data model
</firstterm>.
15589 This model comprises sequences of items. Each item can hold SQL scalar
15590 values, with an additional SQL/JSON null value, and composite data structures
15591 that use JSON arrays and objects. The model is a formalization of the implied
15592 data model in the JSON specification
15593 <ulink url=
"https://datatracker.ietf.org/doc/html/rfc7159">RFC
7159</ulink>.
15597 SQL/JSON allows you to handle JSON data alongside regular SQL data,
15598 with transaction support, including:
15603 Uploading JSON data into the database and storing it in
15604 regular SQL columns as character or binary strings.
15609 Generating JSON objects and arrays from relational data.
15614 Querying JSON data using SQL/JSON query functions and
15615 SQL/JSON path language expressions.
15622 To learn more about the SQL/JSON standard, see
15623 <xref linkend=
"sqltr-19075-6"/>. For details on JSON types
15624 supported in
<productname>PostgreSQL
</productname>,
15625 see
<xref linkend=
"datatype-json"/>.
15628 <sect2 id=
"functions-json-processing">
15629 <title>Processing and Creating JSON Data
</title>
15632 <xref linkend=
"functions-json-op-table"/> shows the operators that
15633 are available for use with JSON data types (see
<xref
15634 linkend=
"datatype-json"/>).
15635 In addition, the usual comparison operators shown in
<xref
15636 linkend=
"functions-comparison-op-table"/> are available for
15637 <type>jsonb
</type>, though not for
<type>json
</type>. The comparison
15638 operators follow the ordering rules for B-tree operations outlined in
15639 <xref linkend=
"json-indexing"/>.
15640 See also
<xref linkend=
"functions-aggregate"/> for the aggregate
15641 function
<function>json_agg
</function> which aggregates record
15642 values as JSON, the aggregate function
15643 <function>json_object_agg
</function> which aggregates pairs of values
15644 into a JSON object, and their
<type>jsonb
</type> equivalents,
15645 <function>jsonb_agg
</function> and
<function>jsonb_object_agg
</function>.
15648 <table id=
"functions-json-op-table">
15649 <title><type>json
</type> and
<type>jsonb
</type> Operators
</title>
15653 <entry role=
"func_table_entry"><para role=
"func_signature">
15667 <entry role=
"func_table_entry"><para role=
"func_signature">
15668 <type>json
</type> <literal>-
></literal> <type>integer
</type>
15669 <returnvalue>json
</returnvalue>
15671 <para role=
"func_signature">
15672 <type>jsonb
</type> <literal>-
></literal> <type>integer
</type>
15673 <returnvalue>jsonb
</returnvalue>
15676 Extracts
<parameter>n
</parameter>'th element of JSON array
15677 (array elements are indexed from zero, but negative integers count
15681 <literal>'[{
"a":
"foo"},{
"b":
"bar"},{
"c":
"baz"}]'::json -
> 2</literal>
15682 <returnvalue>{
"c":
"baz"}
</returnvalue>
15685 <literal>'[{
"a":
"foo"},{
"b":
"bar"},{
"c":
"baz"}]'::json -
> -
3</literal>
15686 <returnvalue>{
"a":
"foo"}
</returnvalue>
15691 <entry role=
"func_table_entry"><para role=
"func_signature">
15692 <type>json
</type> <literal>-
></literal> <type>text
</type>
15693 <returnvalue>json
</returnvalue>
15695 <para role=
"func_signature">
15696 <type>jsonb
</type> <literal>-
></literal> <type>text
</type>
15697 <returnvalue>jsonb
</returnvalue>
15700 Extracts JSON object field with the given key.
15703 <literal>'{
"a": {
"b":
"foo"}}'::json -
> 'a'
</literal>
15704 <returnvalue>{
"b":
"foo"}
</returnvalue>
15709 <entry role=
"func_table_entry"><para role=
"func_signature">
15710 <type>json
</type> <literal>-
>></literal> <type>integer
</type>
15711 <returnvalue>text
</returnvalue>
15713 <para role=
"func_signature">
15714 <type>jsonb
</type> <literal>-
>></literal> <type>integer
</type>
15715 <returnvalue>text
</returnvalue>
15718 Extracts
<parameter>n
</parameter>'th element of JSON array,
15719 as
<type>text
</type>.
15722 <literal>'[
1,
2,
3]'::json -
>> 2</literal>
15723 <returnvalue>3</returnvalue>
15728 <entry role=
"func_table_entry"><para role=
"func_signature">
15729 <type>json
</type> <literal>-
>></literal> <type>text
</type>
15730 <returnvalue>text
</returnvalue>
15732 <para role=
"func_signature">
15733 <type>jsonb
</type> <literal>-
>></literal> <type>text
</type>
15734 <returnvalue>text
</returnvalue>
15737 Extracts JSON object field with the given key, as
<type>text
</type>.
15740 <literal>'{
"a":
1,
"b":
2}'::json -
>> 'b'
</literal>
15741 <returnvalue>2</returnvalue>
15746 <entry role=
"func_table_entry"><para role=
"func_signature">
15747 <type>json
</type> <literal>#
></literal> <type>text[]
</type>
15748 <returnvalue>json
</returnvalue>
15750 <para role=
"func_signature">
15751 <type>jsonb
</type> <literal>#
></literal> <type>text[]
</type>
15752 <returnvalue>jsonb
</returnvalue>
15755 Extracts JSON sub-object at the specified path, where path elements
15756 can be either field keys or array indexes.
15759 <literal>'{
"a": {
"b": [
"foo",
"bar"]}}'::json #
> '{a,b,
1}'
</literal>
15760 <returnvalue>"bar"</returnvalue>
15765 <entry role=
"func_table_entry"><para role=
"func_signature">
15766 <type>json
</type> <literal>#
>></literal> <type>text[]
</type>
15767 <returnvalue>text
</returnvalue>
15769 <para role=
"func_signature">
15770 <type>jsonb
</type> <literal>#
>></literal> <type>text[]
</type>
15771 <returnvalue>text
</returnvalue>
15774 Extracts JSON sub-object at the specified path as
<type>text
</type>.
15777 <literal>'{
"a": {
"b": [
"foo",
"bar"]}}'::json #
>> '{a,b,
1}'
</literal>
15778 <returnvalue>bar
</returnvalue>
15787 The field/element/path extraction operators return NULL, rather than
15788 failing, if the JSON input does not have the right structure to match
15789 the request; for example if no such key or array element exists.
15794 Some further operators exist only for
<type>jsonb
</type>, as shown
15795 in
<xref linkend=
"functions-jsonb-op-table"/>.
15796 <xref linkend=
"json-indexing"/>
15797 describes how these operators can be used to effectively search indexed
15798 <type>jsonb
</type> data.
15801 <table id=
"functions-jsonb-op-table">
15802 <title>Additional
<type>jsonb
</type> Operators
</title>
15806 <entry role=
"func_table_entry"><para role=
"func_signature">
15820 <entry role=
"func_table_entry"><para role=
"func_signature">
15821 <type>jsonb
</type> <literal>@
></literal> <type>jsonb
</type>
15822 <returnvalue>boolean
</returnvalue>
15825 Does the first JSON value contain the second?
15826 (See
<xref linkend=
"json-containment"/> for details about containment.)
15829 <literal>'{
"a":
1,
"b":
2}'::jsonb
@> '{
"b":
2}'::jsonb
</literal>
15830 <returnvalue>t
</returnvalue>
15835 <entry role=
"func_table_entry"><para role=
"func_signature">
15836 <type>jsonb
</type> <literal><@
</literal> <type>jsonb
</type>
15837 <returnvalue>boolean
</returnvalue>
15840 Is the first JSON value contained in the second?
15843 <literal>'{
"b":
2}'::jsonb
<@ '{
"a":
1,
"b":
2}'::jsonb
</literal>
15844 <returnvalue>t
</returnvalue>
15849 <entry role=
"func_table_entry"><para role=
"func_signature">
15850 <type>jsonb
</type> <literal>?
</literal> <type>text
</type>
15851 <returnvalue>boolean
</returnvalue>
15854 Does the text string exist as a top-level key or array element within
15858 <literal>'{
"a":
1,
"b":
2}'::jsonb ? 'b'
</literal>
15859 <returnvalue>t
</returnvalue>
15862 <literal>'[
"a",
"b",
"c"]'::jsonb ? 'b'
</literal>
15863 <returnvalue>t
</returnvalue>
15868 <entry role=
"func_table_entry"><para role=
"func_signature">
15869 <type>jsonb
</type> <literal>?|
</literal> <type>text[]
</type>
15870 <returnvalue>boolean
</returnvalue>
15873 Do any of the strings in the text array exist as top-level keys or
15877 <literal>'{
"a":
1,
"b":
2,
"c":
3}'::jsonb ?| array['b', 'd']
</literal>
15878 <returnvalue>t
</returnvalue>
15883 <entry role=
"func_table_entry"><para role=
"func_signature">
15884 <type>jsonb
</type> <literal>?
&</literal> <type>text[]
</type>
15885 <returnvalue>boolean
</returnvalue>
15888 Do all of the strings in the text array exist as top-level keys or
15892 <literal>'[
"a",
"b",
"c"]'::jsonb ?
& array['a', 'b']
</literal>
15893 <returnvalue>t
</returnvalue>
15898 <entry role=
"func_table_entry"><para role=
"func_signature">
15899 <type>jsonb
</type> <literal>||
</literal> <type>jsonb
</type>
15900 <returnvalue>jsonb
</returnvalue>
15903 Concatenates two
<type>jsonb
</type> values.
15904 Concatenating two arrays generates an array containing all the
15905 elements of each input. Concatenating two objects generates an
15906 object containing the union of their
15907 keys, taking the second object's value when there are duplicate keys.
15908 All other cases are treated by converting a non-array input into a
15909 single-element array, and then proceeding as for two arrays.
15910 Does not operate recursively: only the top-level array or object
15911 structure is merged.
15914 <literal>'[
"a",
"b"]'::jsonb || '[
"a",
"d"]'::jsonb
</literal>
15915 <returnvalue>[
"a",
"b",
"a",
"d"]
</returnvalue>
15918 <literal>'{
"a":
"b"}'::jsonb || '{
"c":
"d"}'::jsonb
</literal>
15919 <returnvalue>{
"a":
"b",
"c":
"d"}
</returnvalue>
15922 <literal>'[
1,
2]'::jsonb || '
3'::jsonb
</literal>
15923 <returnvalue>[
1,
2,
3]
</returnvalue>
15926 <literal>'{
"a":
"b"}'::jsonb || '
42'::jsonb
</literal>
15927 <returnvalue>[{
"a":
"b"},
42]
</returnvalue>
15930 To append an array to another array as a single entry, wrap it
15931 in an additional layer of array, for example:
15934 <literal>'[
1,
2]'::jsonb || jsonb_build_array('[
3,
4]'::jsonb)
</literal>
15935 <returnvalue>[
1,
2, [
3,
4]]
</returnvalue>
15940 <entry role=
"func_table_entry"><para role=
"func_signature">
15941 <type>jsonb
</type> <literal>-
</literal> <type>text
</type>
15942 <returnvalue>jsonb
</returnvalue>
15945 Deletes a key (and its value) from a JSON object, or matching string
15946 value(s) from a JSON array.
15949 <literal>'{
"a":
"b",
"c":
"d"}'::jsonb - 'a'
</literal>
15950 <returnvalue>{
"c":
"d"}
</returnvalue>
15953 <literal>'[
"a",
"b",
"c",
"b"]'::jsonb - 'b'
</literal>
15954 <returnvalue>[
"a",
"c"]
</returnvalue>
15959 <entry role=
"func_table_entry"><para role=
"func_signature">
15960 <type>jsonb
</type> <literal>-
</literal> <type>text[]
</type>
15961 <returnvalue>jsonb
</returnvalue>
15964 Deletes all matching keys or array elements from the left operand.
15967 <literal>'{
"a":
"b",
"c":
"d"}'::jsonb - '{a,c}'::text[]
</literal>
15968 <returnvalue>{}
</returnvalue>
15973 <entry role=
"func_table_entry"><para role=
"func_signature">
15974 <type>jsonb
</type> <literal>-
</literal> <type>integer
</type>
15975 <returnvalue>jsonb
</returnvalue>
15978 Deletes the array element with specified index (negative
15979 integers count from the end). Throws an error if JSON value
15983 <literal>'[
"a",
"b"]'::jsonb -
1 </literal>
15984 <returnvalue>[
"a"]
</returnvalue>
15989 <entry role=
"func_table_entry"><para role=
"func_signature">
15990 <type>jsonb
</type> <literal>#-
</literal> <type>text[]
</type>
15991 <returnvalue>jsonb
</returnvalue>
15994 Deletes the field or array element at the specified path, where path
15995 elements can be either field keys or array indexes.
15998 <literal>'[
"a", {
"b":
1}]'::jsonb #- '{
1,b}'
</literal>
15999 <returnvalue>[
"a", {}]
</returnvalue>
16004 <entry role=
"func_table_entry"><para role=
"func_signature">
16005 <type>jsonb
</type> <literal>@?
</literal> <type>jsonpath
</type>
16006 <returnvalue>boolean
</returnvalue>
16009 Does JSON path return any item for the specified JSON value?
16010 (This is useful only with SQL-standard JSON path expressions, not
16011 <link linkend=
"functions-sqljson-check-expressions">predicate check
16012 expressions
</link>, since those always return a value.)
16015 <literal>'{
"a":[
1,
2,
3,
4,
5]}'::jsonb @? '$.a[*] ? (@
> 2)'
</literal>
16016 <returnvalue>t
</returnvalue>
16021 <entry role=
"func_table_entry"><para role=
"func_signature">
16022 <type>jsonb
</type> <literal>@@
</literal> <type>jsonpath
</type>
16023 <returnvalue>boolean
</returnvalue>
16026 Returns the result of a JSON path predicate check for the
16027 specified JSON value.
16028 (This is useful only
16029 with
<link linkend=
"functions-sqljson-check-expressions">predicate
16030 check expressions
</link>, not SQL-standard JSON path expressions,
16031 since it will return
<literal>NULL
</literal> if the path result is
16032 not a single boolean value.)
16035 <literal>'{
"a":[
1,
2,
3,
4,
5]}'::jsonb @@ '$.a[*]
> 2'
</literal>
16036 <returnvalue>t
</returnvalue>
16045 The
<type>jsonpath
</type> operators
<literal>@?
</literal>
16046 and
<literal>@@
</literal> suppress the following errors: missing object
16047 field or array element, unexpected JSON item type, datetime and numeric
16048 errors. The
<type>jsonpath
</type>-related functions described below can
16049 also be told to suppress these types of errors. This behavior might be
16050 helpful when searching JSON document collections of varying structure.
16055 <xref linkend=
"functions-json-creation-table"/> shows the functions that are
16056 available for constructing
<type>json
</type> and
<type>jsonb
</type> values.
16057 Some functions in this table have a
<literal>RETURNING
</literal> clause,
16058 which specifies the data type returned. It must be one of
<type>json
</type>,
16059 <type>jsonb
</type>,
<type>bytea
</type>, a character string type (
<type>text
</type>,
16060 <type>char
</type>, or
<type>varchar
</type>), or a type
16061 that can be cast to
<type>json
</type>.
16062 By default, the
<type>json
</type> type is returned.
16065 <table id=
"functions-json-creation-table">
16066 <title>JSON Creation Functions
</title>
16070 <entry role=
"func_table_entry"><para role=
"func_signature">
16084 <entry role=
"func_table_entry"><para role=
"func_signature">
16086 <primary>to_json
</primary>
16088 <function>to_json
</function> (
<type>anyelement
</type> )
16089 <returnvalue>json
</returnvalue>
16091 <para role=
"func_signature">
16093 <primary>to_jsonb
</primary>
16095 <function>to_jsonb
</function> (
<type>anyelement
</type> )
16096 <returnvalue>jsonb
</returnvalue>
16099 Converts any SQL value to
<type>json
</type> or
<type>jsonb
</type>.
16100 Arrays and composites are converted recursively to arrays and
16101 objects (multidimensional arrays become arrays of arrays in JSON).
16102 Otherwise, if there is a cast from the SQL data type
16103 to
<type>json
</type>, the cast function will be used to perform the
16104 conversion;
<footnote>
16106 For example, the
<xref linkend=
"hstore"/> extension has a cast
16107 from
<type>hstore
</type> to
<type>json
</type>, so that
16108 <type>hstore
</type> values converted via the JSON creation functions
16109 will be represented as JSON objects, not as primitive string values.
16112 otherwise, a scalar JSON value is produced. For any scalar other than
16113 a number, a Boolean, or a null value, the text representation will be
16114 used, with escaping as necessary to make it a valid JSON string value.
16117 <literal>to_json('Fred said
"Hi."'::text)
</literal>
16118 <returnvalue>"Fred said \"Hi.\
""</returnvalue>
16121 <literal>to_jsonb(row(
42, 'Fred said
"Hi."'::text))
</literal>
16122 <returnvalue>{
"f1":
42,
"f2":
"Fred said \"Hi.\
""}
</returnvalue>
16127 <entry role=
"func_table_entry"><para role=
"func_signature">
16129 <primary>array_to_json
</primary>
16131 <function>array_to_json
</function> (
<type>anyarray
</type> <optional>,
<type>boolean
</type> </optional> )
16132 <returnvalue>json
</returnvalue>
16135 Converts an SQL array to a JSON array. The behavior is the same
16136 as
<function>to_json
</function> except that line feeds will be added
16137 between top-level array elements if the optional boolean parameter is
16141 <literal>array_to_json('{{
1,
5},{
99,
100}}'::int[])
</literal>
16142 <returnvalue>[[
1,
5],[
99,
100]]
</returnvalue>
16148 Note that this is barely legible in the output; it looks like a
16149 salad of braces and brackets. It would be better to split it out
16150 in multiple lines, but that's surprisingly hard to do in a way that
16151 matches in HTML and PDF output. Other standard SQL/JSON functions
16152 have the same problem.
16154 <entry role=
"func_table_entry"><para role=
"func_signature">
16155 <indexterm><primary>json_array
</primary></indexterm>
16156 <function>json_array
</function> (
16157 <optional> {
<replaceable>value_expression
</replaceable> <optional> <literal>FORMAT JSON
</literal> </optional> }
<optional>, ...
</optional> </optional>
16158 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
16159 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
16161 <para role=
"func_signature">
16162 <function>json_array
</function> (
16163 <optional> <replaceable>query_expression
</replaceable> </optional>
16164 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
16167 Constructs a JSON array from either a series of
16168 <replaceable>value_expression
</replaceable> parameters or from the results
16169 of
<replaceable>query_expression
</replaceable>,
16170 which must be a SELECT query returning a single column. If
16171 <literal>ABSENT ON NULL
</literal> is specified, NULL values are ignored.
16172 This is always the case if a
16173 <replaceable>query_expression
</replaceable> is used.
16176 <literal>json_array(
1,true,json '{
"a":null}')
</literal>
16177 <returnvalue>[
1, true, {
"a":null}]
</returnvalue>
16180 <literal>json_array(SELECT * FROM (VALUES(
1),(
2)) t)
</literal>
16181 <returnvalue>[
1,
2]
</returnvalue>
16186 <entry role=
"func_table_entry"><para role=
"func_signature">
16188 <primary>row_to_json
</primary>
16190 <function>row_to_json
</function> (
<type>record
</type> <optional>,
<type>boolean
</type> </optional> )
16191 <returnvalue>json
</returnvalue>
16194 Converts an SQL composite value to a JSON object. The behavior is the
16195 same as
<function>to_json
</function> except that line feeds will be
16196 added between top-level elements if the optional boolean parameter is
16200 <literal>row_to_json(row(
1,'foo'))
</literal>
16201 <returnvalue>{
"f1":
1,
"f2":
"foo"}
</returnvalue>
16206 <entry role=
"func_table_entry"><para role=
"func_signature">
16208 <primary>json_build_array
</primary>
16210 <function>json_build_array
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16211 <returnvalue>json
</returnvalue>
16213 <para role=
"func_signature">
16215 <primary>jsonb_build_array
</primary>
16217 <function>jsonb_build_array
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16218 <returnvalue>jsonb
</returnvalue>
16221 Builds a possibly-heterogeneously-typed JSON array out of a variadic
16222 argument list. Each argument is converted as
16223 per
<function>to_json
</function> or
<function>to_jsonb
</function>.
16226 <literal>json_build_array(
1,
2, 'foo',
4,
5)
</literal>
16227 <returnvalue>[
1,
2,
"foo",
4,
5]
</returnvalue>
16232 <entry role=
"func_table_entry"><para role=
"func_signature">
16234 <primary>json_build_object
</primary>
16236 <function>json_build_object
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16237 <returnvalue>json
</returnvalue>
16239 <para role=
"func_signature">
16241 <primary>jsonb_build_object
</primary>
16243 <function>jsonb_build_object
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
16244 <returnvalue>jsonb
</returnvalue>
16247 Builds a JSON object out of a variadic argument list. By convention,
16248 the argument list consists of alternating keys and values. Key
16249 arguments are coerced to text; value arguments are converted as
16250 per
<function>to_json
</function> or
<function>to_jsonb
</function>.
16253 <literal>json_build_object('foo',
1,
2, row(
3,'bar'))
</literal>
16254 <returnvalue>{
"foo" :
1,
"2" : {
"f1":
3,
"f2":
"bar"}}
</returnvalue>
16259 <entry role=
"func_table_entry"><para role=
"func_signature">
16260 <indexterm><primary>json_object
</primary></indexterm>
16261 <function>json_object
</function> (
16262 <optional> {
<replaceable>key_expression
</replaceable> {
<literal>VALUE
</literal> | ':' }
16263 <replaceable>value_expression
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> }
<optional>, ...
</optional> </optional>
16264 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
16265 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional> </optional>
16266 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
16269 Constructs a JSON object of all the key/value pairs given,
16270 or an empty object if none are given.
16271 <replaceable>key_expression
</replaceable> is a scalar expression
16272 defining the
<acronym>JSON
</acronym> key, which is
16273 converted to the
<type>text
</type> type.
16274 It cannot be
<literal>NULL
</literal> nor can it
16275 belong to a type that has a cast to the
<type>json
</type> type.
16276 If
<literal>WITH UNIQUE KEYS
</literal> is specified, there must not
16277 be any duplicate
<replaceable>key_expression
</replaceable>.
16278 Any pair for which the
<replaceable>value_expression
</replaceable>
16279 evaluates to
<literal>NULL
</literal> is omitted from the output
16280 if
<literal>ABSENT ON NULL
</literal> is specified;
16281 if
<literal>NULL ON NULL
</literal> is specified or the clause
16282 omitted, the key is included with value
<literal>NULL
</literal>.
16285 <literal>json_object('code' VALUE 'P123', 'title': 'Jaws')
</literal>
16286 <returnvalue>{
"code" :
"P123",
"title" :
"Jaws"}
</returnvalue>
16291 <entry role=
"func_table_entry"><para role=
"func_signature">
16293 <primary>json_object
</primary>
16295 <function>json_object
</function> (
<type>text[]
</type> )
16296 <returnvalue>json
</returnvalue>
16298 <para role=
"func_signature">
16300 <primary>jsonb_object
</primary>
16302 <function>jsonb_object
</function> (
<type>text[]
</type> )
16303 <returnvalue>jsonb
</returnvalue>
16306 Builds a JSON object out of a text array. The array must have either
16307 exactly one dimension with an even number of members, in which case
16308 they are taken as alternating key/value pairs, or two dimensions
16309 such that each inner array has exactly two elements, which
16310 are taken as a key/value pair. All values are converted to JSON
16314 <literal>json_object('{a,
1, b,
"def", c,
3.5}')
</literal>
16315 <returnvalue>{
"a" :
"1",
"b" :
"def",
"c" :
"3.5"}
</returnvalue>
16317 <para><literal>json_object('{{a,
1}, {b,
"def"}, {c,
3.5}}')
</literal>
16318 <returnvalue>{
"a" :
"1",
"b" :
"def",
"c" :
"3.5"}
</returnvalue>
16323 <entry role=
"func_table_entry"><para role=
"func_signature">
16324 <function>json_object
</function> (
<parameter>keys
</parameter> <type>text[]
</type>,
<parameter>values
</parameter> <type>text[]
</type> )
16325 <returnvalue>json
</returnvalue>
16327 <para role=
"func_signature">
16328 <function>jsonb_object
</function> (
<parameter>keys
</parameter> <type>text[]
</type>,
<parameter>values
</parameter> <type>text[]
</type> )
16329 <returnvalue>jsonb
</returnvalue>
16332 This form of
<function>json_object
</function> takes keys and values
16333 pairwise from separate text arrays. Otherwise it is identical to
16334 the one-argument form.
16337 <literal>json_object('{a,b}', '{
1,
2}')
</literal>
16338 <returnvalue>{
"a":
"1",
"b":
"2"}
</returnvalue>
16342 <entry role=
"func_table_entry">
16343 <para role=
"func_signature">
16344 <indexterm><primary>json constructor
</primary></indexterm>
16345 <function>json
</function> (
16346 <replaceable>expression
</replaceable>
16347 <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional></optional>
16348 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional></optional> )
16349 <returnvalue>json
</returnvalue>
16352 Converts a given expression specified as
<type>text
</type> or
16353 <type>bytea
</type> string (in UTF8 encoding) into a JSON
16354 value. If
<replaceable>expression
</replaceable> is NULL, an
16355 <acronym>SQL
</acronym> null value is returned.
16356 If
<literal>WITH UNIQUE
</literal> is specified, the
16357 <replaceable>expression
</replaceable> must not contain any duplicate
16361 <literal>json('{
"a":
123,
"b":[true,
"foo"],
"a":
"bar"}')
</literal>
16362 <returnvalue>{
"a":
123,
"b":[true,
"foo"],
"a":
"bar"}
</returnvalue>
16367 <entry role=
"func_table_entry">
16368 <para role=
"func_signature">
16369 <indexterm><primary>json_scalar
</primary></indexterm>
16370 <function>json_scalar
</function> (
<replaceable>expression
</replaceable> )
16373 Converts a given SQL scalar value into a JSON scalar value.
16374 If the input is NULL, an
<acronym>SQL
</acronym> null is returned. If
16375 the input is number or a boolean value, a corresponding JSON number
16376 or boolean value is returned. For any other value, a JSON string is
16380 <literal>json_scalar(
123.45)
</literal>
16381 <returnvalue>123.45</returnvalue>
16384 <literal>json_scalar(CURRENT_TIMESTAMP)
</literal>
16385 <returnvalue>"2022-05-10T10:51:04.62128-04:00"</returnvalue>
16389 <entry role=
"func_table_entry">
16390 <para role=
"func_signature">
16391 <function>json_serialize
</function> (
16392 <replaceable>expression
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional>
16393 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional> )
16396 Converts an SQL/JSON expression into a character or binary string. The
16397 <replaceable>expression
</replaceable> can be of any JSON type, any
16398 character string type, or
<type>bytea
</type> in UTF8 encoding.
16399 The returned type used in
<literal> RETURNING
</literal> can be any
16400 character string type or
<type>bytea
</type>. The default is
16404 <literal>json_serialize('{
"a" :
1 } ' RETURNING bytea)
</literal>
16405 <returnvalue>\x7b20226122203a2031207d20
</returnvalue>
16413 <xref linkend=
"functions-sqljson-misc" /> details SQL/JSON
16414 facilities for testing JSON.
16417 <table id=
"functions-sqljson-misc">
16418 <title>SQL/JSON Testing Functions
</title>
16422 <entry role=
"func_table_entry"><para role=
"func_signature">
16435 <entry role=
"func_table_entry"><para role=
"func_signature">
16436 <indexterm><primary>IS JSON
</primary></indexterm>
16437 <replaceable>expression
</replaceable> <literal>IS
</literal> <optional> <literal>NOT
</literal> </optional> <literal>JSON
</literal>
16438 <optional> {
<literal>VALUE
</literal> |
<literal>SCALAR
</literal> |
<literal>ARRAY
</literal> |
<literal>OBJECT
</literal> }
</optional>
16439 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional> </optional>
16442 This predicate tests whether
<replaceable>expression
</replaceable> can be
16443 parsed as JSON, possibly of a specified type.
16444 If
<literal>SCALAR
</literal> or
<literal>ARRAY
</literal> or
16445 <literal>OBJECT
</literal> is specified, the
16446 test is whether or not the JSON is of that particular type. If
16447 <literal>WITH UNIQUE KEYS
</literal> is specified, then any object in the
16448 <replaceable>expression
</replaceable> is also tested to see if it
16449 has duplicate keys.
16454 js IS JSON
"json?",
16455 js IS JSON SCALAR
"scalar?",
16456 js IS JSON OBJECT
"object?",
16457 js IS JSON ARRAY
"array?"
16459 ('
123'), ('
"abc"'), ('{
"a":
"b"}'), ('[
1,
2]'),('abc')) foo(js);
16460 js | json? | scalar? | object? | array?
16461 ------------+-------+---------+---------+--------
16462 123 | t | t | f | f
16463 "abc" | t | t | f | f
16464 {
"a":
"b"} | t | f | t | f
16465 [
1,
2] | t | f | f | t
16466 abc | f | f | f | f
16472 js IS JSON OBJECT
"object?",
16473 js IS JSON ARRAY
"array?",
16474 js IS JSON ARRAY WITH UNIQUE KEYS
"array w. UK?",
16475 js IS JSON ARRAY WITHOUT UNIQUE KEYS
"array w/o UK?"
16476 FROM (VALUES ('[{
"a":
"1"},
16477 {
"b":
"2",
"b":
"3"}]')) foo(js);
16478 -[ RECORD
1 ]-+--------------------
16480 | {
"b":
"2",
"b":
"3"}]
16493 <xref linkend=
"functions-json-processing-table"/> shows the functions that
16494 are available for processing
<type>json
</type> and
<type>jsonb
</type> values.
16497 <table id=
"functions-json-processing-table">
16498 <title>JSON Processing Functions
</title>
16502 <entry role=
"func_table_entry"><para role=
"func_signature">
16516 <entry role=
"func_table_entry"><para role=
"func_signature">
16518 <primary>json_array_elements
</primary>
16520 <function>json_array_elements
</function> (
<type>json
</type> )
16521 <returnvalue>setof json
</returnvalue>
16523 <para role=
"func_signature">
16525 <primary>jsonb_array_elements
</primary>
16527 <function>jsonb_array_elements
</function> (
<type>jsonb
</type> )
16528 <returnvalue>setof jsonb
</returnvalue>
16531 Expands the top-level JSON array into a set of JSON values.
16534 <literal>select * from json_array_elements('[
1,true, [
2,false]]')
</literal>
16535 <returnvalue></returnvalue>
16547 <entry role=
"func_table_entry"><para role=
"func_signature">
16549 <primary>json_array_elements_text
</primary>
16551 <function>json_array_elements_text
</function> (
<type>json
</type> )
16552 <returnvalue>setof text
</returnvalue>
16554 <para role=
"func_signature">
16556 <primary>jsonb_array_elements_text
</primary>
16558 <function>jsonb_array_elements_text
</function> (
<type>jsonb
</type> )
16559 <returnvalue>setof text
</returnvalue>
16562 Expands the top-level JSON array into a set of
<type>text
</type> values.
16565 <literal>select * from json_array_elements_text('[
"foo",
"bar"]')
</literal>
16566 <returnvalue></returnvalue>
16577 <entry role=
"func_table_entry"><para role=
"func_signature">
16579 <primary>json_array_length
</primary>
16581 <function>json_array_length
</function> (
<type>json
</type> )
16582 <returnvalue>integer
</returnvalue>
16584 <para role=
"func_signature">
16586 <primary>jsonb_array_length
</primary>
16588 <function>jsonb_array_length
</function> (
<type>jsonb
</type> )
16589 <returnvalue>integer
</returnvalue>
16592 Returns the number of elements in the top-level JSON array.
16595 <literal>json_array_length('[
1,
2,
3,{
"f1":
1,
"f2":[
5,
6]},
4]')
</literal>
16596 <returnvalue>5</returnvalue>
16599 <literal>jsonb_array_length('[]')
</literal>
16600 <returnvalue>0</returnvalue>
16605 <entry role=
"func_table_entry"><para role=
"func_signature">
16607 <primary>json_each
</primary>
16609 <function>json_each
</function> (
<type>json
</type> )
16610 <returnvalue>setof record
</returnvalue>
16611 (
<parameter>key
</parameter> <type>text
</type>,
16612 <parameter>value
</parameter> <type>json
</type> )
16614 <para role=
"func_signature">
16616 <primary>jsonb_each
</primary>
16618 <function>jsonb_each
</function> (
<type>jsonb
</type> )
16619 <returnvalue>setof record
</returnvalue>
16620 (
<parameter>key
</parameter> <type>text
</type>,
16621 <parameter>value
</parameter> <type>jsonb
</type> )
16624 Expands the top-level JSON object into a set of key/value pairs.
16627 <literal>select * from json_each('{
"a":
"foo",
"b":
"bar"}')
</literal>
16628 <returnvalue></returnvalue>
16639 <entry role=
"func_table_entry"><para role=
"func_signature">
16641 <primary>json_each_text
</primary>
16643 <function>json_each_text
</function> (
<type>json
</type> )
16644 <returnvalue>setof record
</returnvalue>
16645 (
<parameter>key
</parameter> <type>text
</type>,
16646 <parameter>value
</parameter> <type>text
</type> )
16648 <para role=
"func_signature">
16650 <primary>jsonb_each_text
</primary>
16652 <function>jsonb_each_text
</function> (
<type>jsonb
</type> )
16653 <returnvalue>setof record
</returnvalue>
16654 (
<parameter>key
</parameter> <type>text
</type>,
16655 <parameter>value
</parameter> <type>text
</type> )
16658 Expands the top-level JSON object into a set of key/value pairs.
16659 The returned
<parameter>value
</parameter>s will be of
16660 type
<type>text
</type>.
16663 <literal>select * from json_each_text('{
"a":
"foo",
"b":
"bar"}')
</literal>
16664 <returnvalue></returnvalue>
16675 <entry role=
"func_table_entry"><para role=
"func_signature">
16677 <primary>json_extract_path
</primary>
16679 <function>json_extract_path
</function> (
<parameter>from_json
</parameter> <type>json
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16680 <returnvalue>json
</returnvalue>
16682 <para role=
"func_signature">
16684 <primary>jsonb_extract_path
</primary>
16686 <function>jsonb_extract_path
</function> (
<parameter>from_json
</parameter> <type>jsonb
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16687 <returnvalue>jsonb
</returnvalue>
16690 Extracts JSON sub-object at the specified path.
16691 (This is functionally equivalent to the
<literal>#
></literal>
16692 operator, but writing the path out as a variadic list can be more
16693 convenient in some cases.)
16696 <literal>json_extract_path('{
"f2":{
"f3":
1},
"f4":{
"f5":
99,
"f6":
"foo"}}', 'f4', 'f6')
</literal>
16697 <returnvalue>"foo"</returnvalue>
16702 <entry role=
"func_table_entry"><para role=
"func_signature">
16704 <primary>json_extract_path_text
</primary>
16706 <function>json_extract_path_text
</function> (
<parameter>from_json
</parameter> <type>json
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16707 <returnvalue>text
</returnvalue>
16709 <para role=
"func_signature">
16711 <primary>jsonb_extract_path_text
</primary>
16713 <function>jsonb_extract_path_text
</function> (
<parameter>from_json
</parameter> <type>jsonb
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16714 <returnvalue>text
</returnvalue>
16717 Extracts JSON sub-object at the specified path as
<type>text
</type>.
16718 (This is functionally equivalent to the
<literal>#
>></literal>
16722 <literal>json_extract_path_text('{
"f2":{
"f3":
1},
"f4":{
"f5":
99,
"f6":
"foo"}}', 'f4', 'f6')
</literal>
16723 <returnvalue>foo
</returnvalue>
16728 <entry role=
"func_table_entry"><para role=
"func_signature">
16730 <primary>json_object_keys
</primary>
16732 <function>json_object_keys
</function> (
<type>json
</type> )
16733 <returnvalue>setof text
</returnvalue>
16735 <para role=
"func_signature">
16737 <primary>jsonb_object_keys
</primary>
16739 <function>jsonb_object_keys
</function> (
<type>jsonb
</type> )
16740 <returnvalue>setof text
</returnvalue>
16743 Returns the set of keys in the top-level JSON object.
16746 <literal>select * from json_object_keys('{
"f1":
"abc",
"f2":{
"f3":
"a",
"f4":
"b"}}')
</literal>
16747 <returnvalue></returnvalue>
16758 <entry role=
"func_table_entry"><para role=
"func_signature">
16760 <primary>json_populate_record
</primary>
16762 <function>json_populate_record
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16763 <returnvalue>anyelement
</returnvalue>
16765 <para role=
"func_signature">
16767 <primary>jsonb_populate_record
</primary>
16769 <function>jsonb_populate_record
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>jsonb
</type> )
16770 <returnvalue>anyelement
</returnvalue>
16773 Expands the top-level JSON object to a row having the composite type
16774 of the
<parameter>base
</parameter> argument. The JSON object
16775 is scanned for fields whose names match column names of the output row
16776 type, and their values are inserted into those columns of the output.
16777 (Fields that do not correspond to any output column name are ignored.)
16778 In typical use, the value of
<parameter>base
</parameter> is just
16779 <literal>NULL
</literal>, which means that any output columns that do
16780 not match any object field will be filled with nulls. However,
16781 if
<parameter>base
</parameter> isn't
<literal>NULL
</literal> then
16782 the values it contains will be used for unmatched columns.
16785 To convert a JSON value to the SQL type of an output column, the
16786 following rules are applied in sequence:
16787 <itemizedlist spacing=
"compact">
16790 A JSON null value is converted to an SQL null in all cases.
16795 If the output column is of type
<type>json
</type>
16796 or
<type>jsonb
</type>, the JSON value is just reproduced exactly.
16801 If the output column is a composite (row) type, and the JSON value
16802 is a JSON object, the fields of the object are converted to columns
16803 of the output row type by recursive application of these rules.
16808 Likewise, if the output column is an array type and the JSON value
16809 is a JSON array, the elements of the JSON array are converted to
16810 elements of the output array by recursive application of these
16816 Otherwise, if the JSON value is a string, the contents of the
16817 string are fed to the input conversion function for the column's
16823 Otherwise, the ordinary text representation of the JSON value is
16824 fed to the input conversion function for the column's data type.
16830 While the example below uses a constant JSON value, typical use would
16831 be to reference a
<type>json
</type> or
<type>jsonb
</type> column
16832 laterally from another table in the query's
<literal>FROM
</literal>
16833 clause. Writing
<function>json_populate_record
</function> in
16834 the
<literal>FROM
</literal> clause is good practice, since all of the
16835 extracted columns are available for use without duplicate function
16839 <literal>create type subrowtype as (d int, e text);
</literal>
16840 <literal>create type myrowtype as (a int, b text[], c subrowtype);
</literal>
16843 <literal>select * from json_populate_record(null::myrowtype,
16844 '{
"a":
1,
"b": [
"2",
"a b"],
"c": {
"d":
4,
"e":
"a b c"},
"x":
"foo"}')
</literal>
16845 <returnvalue></returnvalue>
16848 ---+-----------+-------------
16849 1 | {
2,
"a b"} | (
4,
"a b c")
16855 <entry role=
"func_table_entry"><para role=
"func_signature">
16857 <primary>jsonb_populate_record_valid
</primary>
16859 <function>jsonb_populate_record_valid
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16860 <returnvalue>boolean
</returnvalue>
16863 Function for testing
<function>jsonb_populate_record
</function>. Returns
16864 <literal>true
</literal> if the input
<function>jsonb_populate_record
</function>
16865 would finish without an error for the given input JSON object; that is, it's
16866 valid input,
<literal>false
</literal> otherwise.
16869 <literal>create type jsb_char2 as (a char(
2));
</literal>
16872 <literal>select jsonb_populate_record_valid(NULL::jsb_char2, '{
"a":
"aaa"}');
</literal>
16873 <returnvalue></returnvalue>
16875 jsonb_populate_record_valid
16876 -----------------------------
16881 <literal>select * from jsonb_populate_record(NULL::jsb_char2, '{
"a":
"aaa"}') q;
</literal>
16882 <returnvalue></returnvalue>
16884 ERROR: value too long for type character(
2)
16886 <literal>select jsonb_populate_record_valid(NULL::jsb_char2, '{
"a":
"aa"}');
</literal>
16887 <returnvalue></returnvalue>
16889 jsonb_populate_record_valid
16890 -----------------------------
16895 <literal>select * from jsonb_populate_record(NULL::jsb_char2, '{
"a":
"aa"}') q;
</literal>
16896 <returnvalue></returnvalue>
16907 <entry role=
"func_table_entry"><para role=
"func_signature">
16909 <primary>json_populate_recordset
</primary>
16911 <function>json_populate_recordset
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16912 <returnvalue>setof anyelement
</returnvalue>
16914 <para role=
"func_signature">
16916 <primary>jsonb_populate_recordset
</primary>
16918 <function>jsonb_populate_recordset
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>jsonb
</type> )
16919 <returnvalue>setof anyelement
</returnvalue>
16922 Expands the top-level JSON array of objects to a set of rows having
16923 the composite type of the
<parameter>base
</parameter> argument.
16924 Each element of the JSON array is processed as described above
16925 for
<function>json[b]_populate_record
</function>.
16928 <literal>create type twoints as (a int, b int);
</literal>
16931 <literal>select * from json_populate_recordset(null::twoints, '[{
"a":
1,
"b":
2}, {
"a":
3,
"b":
4}]')
</literal>
16932 <returnvalue></returnvalue>
16943 <entry role=
"func_table_entry"><para role=
"func_signature">
16945 <primary>json_to_record
</primary>
16947 <function>json_to_record
</function> (
<type>json
</type> )
16948 <returnvalue>record
</returnvalue>
16950 <para role=
"func_signature">
16952 <primary>jsonb_to_record
</primary>
16954 <function>jsonb_to_record
</function> (
<type>jsonb
</type> )
16955 <returnvalue>record
</returnvalue>
16958 Expands the top-level JSON object to a row having the composite type
16959 defined by an
<literal>AS
</literal> clause. (As with all functions
16960 returning
<type>record
</type>, the calling query must explicitly
16961 define the structure of the record with an
<literal>AS
</literal>
16962 clause.) The output record is filled from fields of the JSON object,
16963 in the same way as described above
16964 for
<function>json[b]_populate_record
</function>. Since there is no
16965 input record value, unmatched columns are always filled with nulls.
16968 <literal>create type myrowtype as (a int, b text);
</literal>
16971 <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>
16972 <returnvalue></returnvalue>
16975 ---+---------+---------+---+---------------
16976 1 | [
1,
2,
3] | {
1,
2,
3} | | (
123,
"a b c")
16982 <entry role=
"func_table_entry"><para role=
"func_signature">
16984 <primary>json_to_recordset
</primary>
16986 <function>json_to_recordset
</function> (
<type>json
</type> )
16987 <returnvalue>setof record
</returnvalue>
16989 <para role=
"func_signature">
16991 <primary>jsonb_to_recordset
</primary>
16993 <function>jsonb_to_recordset
</function> (
<type>jsonb
</type> )
16994 <returnvalue>setof record
</returnvalue>
16997 Expands the top-level JSON array of objects to a set of rows having
16998 the composite type defined by an
<literal>AS
</literal> clause. (As
16999 with all functions returning
<type>record
</type>, the calling query
17000 must explicitly define the structure of the record with
17001 an
<literal>AS
</literal> clause.) Each element of the JSON array is
17002 processed as described above
17003 for
<function>json[b]_populate_record
</function>.
17006 <literal>select * from json_to_recordset('[{
"a":
1,
"b":
"foo"}, {
"a":
"2",
"c":
"bar"}]') as x(a int, b text)
</literal>
17007 <returnvalue></returnvalue>
17018 <entry role=
"func_table_entry"><para role=
"func_signature">
17020 <primary>jsonb_set
</primary>
17022 <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> )
17023 <returnvalue>jsonb
</returnvalue>
17026 Returns
<parameter>target
</parameter>
17027 with the item designated by
<parameter>path
</parameter>
17028 replaced by
<parameter>new_value
</parameter>, or with
17029 <parameter>new_value
</parameter> added if
17030 <parameter>create_if_missing
</parameter> is true (which is the
17031 default) and the item designated by
<parameter>path
</parameter>
17033 All earlier steps in the path must exist, or
17034 the
<parameter>target
</parameter> is returned unchanged.
17035 As with the path oriented operators, negative integers that
17036 appear in the
<parameter>path
</parameter> count from the end
17038 If the last path step is an array index that is out of range,
17039 and
<parameter>create_if_missing
</parameter> is true, the new
17040 value is added at the beginning of the array if the index is negative,
17041 or at the end of the array if it is positive.
17044 <literal>jsonb_set('[{
"f1":
1,
"f2":null},
2,null,
3]', '{
0,f1}', '[
2,
3,
4]', false)
</literal>
17045 <returnvalue>[{
"f1": [
2,
3,
4],
"f2": null},
2, null,
3]
</returnvalue>
17048 <literal>jsonb_set('[{
"f1":
1,
"f2":null},
2]', '{
0,f3}', '[
2,
3,
4]')
</literal>
17049 <returnvalue>[{
"f1":
1,
"f2": null,
"f3": [
2,
3,
4]},
2]
</returnvalue>
17054 <entry role=
"func_table_entry"><para role=
"func_signature">
17056 <primary>jsonb_set_lax
</primary>
17058 <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> )
17059 <returnvalue>jsonb
</returnvalue>
17062 If
<parameter>new_value
</parameter> is not
<literal>NULL
</literal>,
17063 behaves identically to
<literal>jsonb_set
</literal>. Otherwise behaves
17064 according to the value
17065 of
<parameter>null_value_treatment
</parameter> which must be one
17066 of
<literal>'raise_exception'
</literal>,
17067 <literal>'use_json_null'
</literal>,
<literal>'delete_key'
</literal>, or
17068 <literal>'return_target'
</literal>. The default is
17069 <literal>'use_json_null'
</literal>.
17072 <literal>jsonb_set_lax('[{
"f1":
1,
"f2":null},
2,null,
3]', '{
0,f1}', null)
</literal>
17073 <returnvalue>[{
"f1": null,
"f2": null},
2, null,
3]
</returnvalue>
17076 <literal>jsonb_set_lax('[{
"f1":
99,
"f2":null},
2]', '{
0,f3}', null, true, 'return_target')
</literal>
17077 <returnvalue>[{
"f1":
99,
"f2": null},
2]
</returnvalue>
17082 <entry role=
"func_table_entry"><para role=
"func_signature">
17084 <primary>jsonb_insert
</primary>
17086 <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> )
17087 <returnvalue>jsonb
</returnvalue>
17090 Returns
<parameter>target
</parameter>
17091 with
<parameter>new_value
</parameter> inserted. If the item
17092 designated by the
<parameter>path
</parameter> is an array
17093 element,
<parameter>new_value
</parameter> will be inserted before
17094 that item if
<parameter>insert_after
</parameter> is false (which
17095 is the default), or after it
17096 if
<parameter>insert_after
</parameter> is true. If the item
17097 designated by the
<parameter>path
</parameter> is an object
17098 field,
<parameter>new_value
</parameter> will be inserted only if
17099 the object does not already contain that key.
17100 All earlier steps in the path must exist, or
17101 the
<parameter>target
</parameter> is returned unchanged.
17102 As with the path oriented operators, negative integers that
17103 appear in the
<parameter>path
</parameter> count from the end
17105 If the last path step is an array index that is out of range, the new
17106 value is added at the beginning of the array if the index is negative,
17107 or at the end of the array if it is positive.
17110 <literal>jsonb_insert('{
"a": [
0,
1,
2]}', '{a,
1}', '
"new_value"')
</literal>
17111 <returnvalue>{
"a": [
0,
"new_value",
1,
2]}
</returnvalue>
17114 <literal>jsonb_insert('{
"a": [
0,
1,
2]}', '{a,
1}', '
"new_value"', true)
</literal>
17115 <returnvalue>{
"a": [
0,
1,
"new_value",
2]}
</returnvalue>
17120 <entry role=
"func_table_entry"><para role=
"func_signature">
17122 <primary>json_strip_nulls
</primary>
17124 <function>json_strip_nulls
</function> (
<type>json
</type> )
17125 <returnvalue>json
</returnvalue>
17127 <para role=
"func_signature">
17129 <primary>jsonb_strip_nulls
</primary>
17131 <function>jsonb_strip_nulls
</function> (
<type>jsonb
</type> )
17132 <returnvalue>jsonb
</returnvalue>
17135 Deletes all object fields that have null values from the given JSON
17136 value, recursively. Null values that are not object fields are
17140 <literal>json_strip_nulls('[{
"f1":
1,
"f2":null},
2, null,
3]')
</literal>
17141 <returnvalue>[{
"f1":
1},
2,null,
3]
</returnvalue>
17146 <entry role=
"func_table_entry"><para role=
"func_signature">
17148 <primary>jsonb_path_exists
</primary>
17150 <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> )
17151 <returnvalue>boolean
</returnvalue>
17154 Checks whether the JSON path returns any item for the specified JSON
17156 (This is useful only with SQL-standard JSON path expressions, not
17157 <link linkend=
"functions-sqljson-check-expressions">predicate check
17158 expressions
</link>, since those always return a value.)
17159 If the
<parameter>vars
</parameter> argument is specified, it must
17160 be a JSON object, and its fields provide named values to be
17161 substituted into the
<type>jsonpath
</type> expression.
17162 If the
<parameter>silent
</parameter> argument is specified and
17163 is
<literal>true
</literal>, the function suppresses the same errors
17164 as the
<literal>@?
</literal> and
<literal>@@
</literal> operators do.
17167 <literal>jsonb_path_exists('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17168 <returnvalue>t
</returnvalue>
17173 <entry role=
"func_table_entry"><para role=
"func_signature">
17175 <primary>jsonb_path_match
</primary>
17177 <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> )
17178 <returnvalue>boolean
</returnvalue>
17181 Returns the SQL boolean result of a JSON path predicate check
17182 for the specified JSON value.
17183 (This is useful only
17184 with
<link linkend=
"functions-sqljson-check-expressions">predicate
17185 check expressions
</link>, not SQL-standard JSON path expressions,
17186 since it will either fail or return
<literal>NULL
</literal> if the
17187 path result is not a single boolean value.)
17188 The optional
<parameter>vars
</parameter>
17189 and
<parameter>silent
</parameter> arguments act the same as
17190 for
<function>jsonb_path_exists
</function>.
17193 <literal>jsonb_path_match('{
"a":[
1,
2,
3,
4,
5]}', 'exists($.a[*] ? (@
>= $min
&& @
<= $max))', '{
"min":
2,
"max":
4}')
</literal>
17194 <returnvalue>t
</returnvalue>
17199 <entry role=
"func_table_entry"><para role=
"func_signature">
17201 <primary>jsonb_path_query
</primary>
17203 <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> )
17204 <returnvalue>setof jsonb
</returnvalue>
17207 Returns all JSON items returned by the JSON path for the specified
17209 For SQL-standard JSON path expressions it returns the JSON
17210 values selected from
<parameter>target
</parameter>.
17211 For
<link linkend=
"functions-sqljson-check-expressions">predicate
17212 check expressions
</link> it returns the result of the predicate
17213 check:
<literal>true
</literal>,
<literal>false
</literal>,
17214 or
<literal>null
</literal>.
17215 The optional
<parameter>vars
</parameter>
17216 and
<parameter>silent
</parameter> arguments act the same as
17217 for
<function>jsonb_path_exists
</function>.
17220 <literal>select * from jsonb_path_query('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17221 <returnvalue></returnvalue>
17233 <entry role=
"func_table_entry"><para role=
"func_signature">
17235 <primary>jsonb_path_query_array
</primary>
17237 <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> )
17238 <returnvalue>jsonb
</returnvalue>
17241 Returns all JSON items returned by the JSON path for the specified
17242 JSON value, as a JSON array.
17243 The parameters are the same as
17244 for
<function>jsonb_path_query
</function>.
17247 <literal>jsonb_path_query_array('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17248 <returnvalue>[
2,
3,
4]
</returnvalue>
17253 <entry role=
"func_table_entry"><para role=
"func_signature">
17255 <primary>jsonb_path_query_first
</primary>
17257 <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> )
17258 <returnvalue>jsonb
</returnvalue>
17261 Returns the first JSON item returned by the JSON path for the
17262 specified JSON value, or
<literal>NULL
</literal> if there are no
17264 The parameters are the same as
17265 for
<function>jsonb_path_query
</function>.
17268 <literal>jsonb_path_query_first('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
17269 <returnvalue>2</returnvalue>
17274 <entry role=
"func_table_entry"><para role=
"func_signature">
17276 <primary>jsonb_path_exists_tz
</primary>
17278 <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> )
17279 <returnvalue>boolean
</returnvalue>
17281 <para role=
"func_signature">
17283 <primary>jsonb_path_match_tz
</primary>
17285 <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> )
17286 <returnvalue>boolean
</returnvalue>
17288 <para role=
"func_signature">
17290 <primary>jsonb_path_query_tz
</primary>
17292 <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> )
17293 <returnvalue>setof jsonb
</returnvalue>
17295 <para role=
"func_signature">
17297 <primary>jsonb_path_query_array_tz
</primary>
17299 <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> )
17300 <returnvalue>jsonb
</returnvalue>
17302 <para role=
"func_signature">
17304 <primary>jsonb_path_query_first_tz
</primary>
17306 <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> )
17307 <returnvalue>jsonb
</returnvalue>
17310 These functions act like their counterparts described above without
17311 the
<literal>_tz
</literal> suffix, except that these functions support
17312 comparisons of date/time values that require timezone-aware
17313 conversions. The example below requires interpretation of the
17314 date-only value
<literal>2015-
08-
02</literal> as a timestamp with time
17315 zone, so the result depends on the current
17316 <xref linkend=
"guc-timezone"/> setting. Due to this dependency, these
17317 functions are marked as stable, which means these functions cannot be
17318 used in indexes. Their counterparts are immutable, and so can be used
17319 in indexes; but they will throw errors if asked to make such
17323 <literal>jsonb_path_exists_tz('[
"2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime()
< "2015-08-02".datetime())')
</literal>
17324 <returnvalue>t
</returnvalue>
17329 <entry role=
"func_table_entry"><para role=
"func_signature">
17331 <primary>jsonb_pretty
</primary>
17333 <function>jsonb_pretty
</function> (
<type>jsonb
</type> )
17334 <returnvalue>text
</returnvalue>
17337 Converts the given JSON value to pretty-printed, indented text.
17340 <literal>jsonb_pretty('[{
"f1":
1,
"f2":null},
2]')
</literal>
17341 <returnvalue></returnvalue>
17355 <entry role=
"func_table_entry"><para role=
"func_signature">
17357 <primary>json_typeof
</primary>
17359 <function>json_typeof
</function> (
<type>json
</type> )
17360 <returnvalue>text
</returnvalue>
17362 <para role=
"func_signature">
17364 <primary>jsonb_typeof
</primary>
17366 <function>jsonb_typeof
</function> (
<type>jsonb
</type> )
17367 <returnvalue>text
</returnvalue>
17370 Returns the type of the top-level JSON value as a text string.
17372 <literal>object
</literal>,
<literal>array
</literal>,
17373 <literal>string
</literal>,
<literal>number
</literal>,
17374 <literal>boolean
</literal>, and
<literal>null
</literal>.
17375 (The
<literal>null
</literal> result should not be confused
17376 with an SQL NULL; see the examples.)
17379 <literal>json_typeof('-
123.4')
</literal>
17380 <returnvalue>number
</returnvalue>
17383 <literal>json_typeof('null'::json)
</literal>
17384 <returnvalue>null
</returnvalue>
17387 <literal>json_typeof(NULL::json) IS NULL
</literal>
17388 <returnvalue>t
</returnvalue>
17396 <sect2 id=
"functions-sqljson-path">
17397 <title>The SQL/JSON Path Language
</title>
17399 <indexterm zone=
"functions-sqljson-path">
17400 <primary>SQL/JSON path language
</primary>
17404 SQL/JSON path expressions specify item(s) to be retrieved
17405 from a JSON value, similarly to XPath expressions used
17406 for access to XML content. In
<productname>PostgreSQL
</productname>,
17407 path expressions are implemented as the
<type>jsonpath
</type>
17408 data type and can use any elements described in
17409 <xref linkend=
"datatype-jsonpath"/>.
17413 JSON query functions and operators
17414 pass the provided path expression to the
<firstterm>path engine
</firstterm>
17415 for evaluation. If the expression matches the queried JSON data,
17416 the corresponding JSON item, or set of items, is returned.
17417 If there is no match, the result will be
<literal>NULL
</literal>,
17418 <literal>false
</literal>, or an error, depending on the function.
17419 Path expressions are written in the SQL/JSON path language
17420 and can include arithmetic expressions and functions.
17424 A path expression consists of a sequence of elements allowed
17425 by the
<type>jsonpath
</type> data type.
17426 The path expression is normally evaluated from left to right, but
17427 you can use parentheses to change the order of operations.
17428 If the evaluation is successful, a sequence of JSON items is produced,
17429 and the evaluation result is returned to the JSON query function
17430 that completes the specified computation.
17434 To refer to the JSON value being queried (the
17435 <firstterm>context item
</firstterm>), use the
<literal>$
</literal> variable
17436 in the path expression. The first element of a path must always
17437 be
<literal>$
</literal>. It can be followed by one or more
17438 <link linkend=
"type-jsonpath-accessors">accessor operators
</link>,
17439 which go down the JSON structure level by level to retrieve sub-items
17440 of the context item. Each accessor operator acts on the
17441 result(s) of the previous evaluation step, producing zero, one, or more
17442 output items from each input item.
17446 For example, suppose you have some JSON data from a GPS tracker that you
17447 would like to parse, such as:
17453 "location": [
47.763,
13.4034 ],
17454 "start time":
"2018-10-14 10:05:14",
17458 "location": [
47.706,
13.2635 ],
17459 "start time":
"2018-10-14 10:39:21",
17466 (The above example can be copied-and-pasted
17467 into
<application>psql
</application> to set things up for the following
17468 examples. Then
<application>psql
</application> will
17469 expand
<literal>:'json'
</literal> into a suitably-quoted string
17470 constant containing the JSON value.)
17474 To retrieve the available track segments, you need to use the
17475 <literal>.
<replaceable>key
</replaceable></literal> accessor
17476 operator to descend through surrounding JSON objects, for example:
17478 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments');
</userinput>
17480 -----------------------------------------------------------
&zwsp;-----------------------------------------------------------
&zwsp;---------------------------------------------
17481 [{
"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"}]
17486 To retrieve the contents of an array, you typically use the
17487 <literal>[*]
</literal> operator.
17488 The following example will return the location coordinates for all
17489 the available track segments:
17491 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].location');
</userinput>
17493 -------------------
17497 Here we started with the whole JSON input value (
<literal>$
</literal>),
17498 then the
<literal>.track
</literal> accessor selected the JSON object
17499 associated with the
<literal>"track"</literal> object key, then
17500 the
<literal>.segments
</literal> accessor selected the JSON array
17501 associated with the
<literal>"segments"</literal> key within that
17502 object, then the
<literal>[*]
</literal> accessor selected each element
17503 of that array (producing a series of items), then
17504 the
<literal>.location
</literal> accessor selected the JSON array
17505 associated with the
<literal>"location"</literal> key within each of
17506 those objects. In this example, each of those objects had
17507 a
<literal>"location"</literal> key; but if any of them did not,
17508 the
<literal>.location
</literal> accessor would have simply produced no
17509 output for that input item.
17513 To return the coordinates of the first segment only, you can
17514 specify the corresponding subscript in the
<literal>[]
</literal>
17515 accessor operator. Recall that JSON array indexes are
0-relative:
17517 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[
0].location');
</userinput>
17519 -------------------
17525 The result of each path evaluation step can be processed
17526 by one or more of the
<type>jsonpath
</type> operators and methods
17527 listed in
<xref linkend=
"functions-sqljson-path-operators"/>.
17528 Each method name must be preceded by a dot. For example,
17529 you can get the size of an array:
17531 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments.size()');
</userinput>
17536 More examples of using
<type>jsonpath
</type> operators
17537 and methods within path expressions appear below in
17538 <xref linkend=
"functions-sqljson-path-operators"/>.
17542 A path can also contain
17543 <firstterm>filter expressions
</firstterm> that work similarly to the
17544 <literal>WHERE
</literal> clause in SQL. A filter expression begins with
17545 a question mark and provides a condition in parentheses:
17548 ? (
<replaceable>condition
</replaceable>)
17553 Filter expressions must be written just after the path evaluation step
17554 to which they should apply. The result of that step is filtered to include
17555 only those items that satisfy the provided condition. SQL/JSON defines
17556 three-valued logic, so the condition can
17557 produce
<literal>true
</literal>,
<literal>false
</literal>,
17558 or
<literal>unknown
</literal>. The
<literal>unknown
</literal> value
17559 plays the same role as SQL
<literal>NULL
</literal> and can be tested
17560 for with the
<literal>is unknown
</literal> predicate. Further path
17561 evaluation steps use only those items for which the filter expression
17562 returned
<literal>true
</literal>.
17566 The functions and operators that can be used in filter expressions are
17567 listed in
<xref linkend=
"functions-sqljson-filter-ex-table"/>. Within a
17568 filter expression, the
<literal>@
</literal> variable denotes the value
17569 being considered (i.e., one result of the preceding path step). You can
17570 write accessor operators after
<literal>@
</literal> to retrieve component
17575 For example, suppose you would like to retrieve all heart rate values higher
17576 than
130. You can achieve this as follows:
17578 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].HR ? (@
> 130)');
</userinput>
17586 To get the start times of segments with such values, you have to
17587 filter out irrelevant segments before selecting the start times, so the
17588 filter expression is applied to the previous step, and the path used
17589 in the condition is different:
17591 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.HR
> 130).
"start time"');
</userinput>
17593 -----------------------
17594 "2018-10-14 10:39:21"
17599 You can use several filter expressions in sequence, if required.
17600 The following example selects start times of all segments that
17601 contain locations with relevant coordinates and high heart rate values:
17603 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[
1]
< 13.4) ? (@.HR
> 130).
"start time"');
</userinput>
17605 -----------------------
17606 "2018-10-14 10:39:21"
17611 Using filter expressions at different nesting levels is also allowed.
17612 The following example first filters all segments by location, and then
17613 returns high heart rate values for these segments, if available:
17615 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*] ? (@.location[
1]
< 13.4).HR ? (@
> 130)');
</userinput>
17623 You can also nest filter expressions within each other.
17624 This example returns the size of the track if it contains any
17625 segments with high heart rate values, or an empty sequence otherwise:
17627 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track ? (exists(@.segments[*] ? (@.HR
> 130))).segments.size()');
</userinput>
17634 <sect3 id=
"functions-sqljson-deviations">
17635 <title>Deviations from the SQL Standard
</title>
17637 <productname>PostgreSQL
</productname>'s implementation of the SQL/JSON path
17638 language has the following deviations from the SQL/JSON standard.
17641 <sect4 id=
"functions-sqljson-check-expressions">
17642 <title>Boolean Predicate Check Expressions
</title>
17644 As an extension to the SQL standard,
17645 a
<productname>PostgreSQL
</productname> path expression can be a
17646 Boolean predicate, whereas the SQL standard allows predicates only within
17647 filters. While SQL-standard path expressions return the relevant
17648 element(s) of the queried JSON value, predicate check expressions
17649 return the single three-valued
<type>jsonb
</type> result of the
17650 predicate:
<literal>true
</literal>,
17651 <literal>false
</literal>, or
<literal>null
</literal>.
17652 For example, we could write this SQL-standard filter expression:
17654 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments ?(@[*].HR
> 130)');
</userinput>
17656 -----------------------------------------------------------
&zwsp;----------------------
17657 {
"HR":
135,
"location": [
47.706,
13.2635],
"start time":
"2018-10-14 10:39:21"}
17659 The similar predicate check expression simply
17660 returns
<literal>true
</literal>, indicating that a match exists:
17662 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', '$.track.segments[*].HR
> 130');
</userinput>
17671 Predicate check expressions are required in the
17672 <literal>@@
</literal> operator (and the
17673 <function>jsonb_path_match
</function> function), and should not be used
17674 with the
<literal>@?
</literal> operator (or the
17675 <function>jsonb_path_exists
</function> function).
17680 <sect4 id=
"functions-sqljson-regular-expression-deviation">
17681 <title>Regular Expression Interpretation
</title>
17683 There are minor differences in the interpretation of regular
17684 expression patterns used in
<literal>like_regex
</literal> filters, as
17685 described in
<xref linkend=
"jsonpath-regular-expressions"/>.
17690 <sect3 id=
"functions-sqljson-strict-and-lax-modes">
17691 <title>Strict and Lax Modes
</title>
17693 When you query JSON data, the path expression may not match the
17694 actual JSON data structure. An attempt to access a non-existent
17695 member of an object or element of an array is defined as a
17696 structural error. SQL/JSON path expressions have two modes
17697 of handling structural errors:
17703 lax (default)
— the path engine implicitly adapts
17704 the queried data to the specified path.
17705 Any structural errors that cannot be fixed as described below
17706 are suppressed, producing no match.
17711 strict
— if a structural error occurs, an error is raised.
17717 Lax mode facilitates matching of a JSON document and path
17718 expression when the JSON data does not conform to the expected schema.
17719 If an operand does not match the requirements of a particular operation,
17720 it can be automatically wrapped as an SQL/JSON array, or unwrapped by
17721 converting its elements into an SQL/JSON sequence before performing
17722 the operation. Also, comparison operators automatically unwrap their
17723 operands in lax mode, so you can compare SQL/JSON arrays
17724 out-of-the-box. An array of size
1 is considered equal to its sole element.
17725 Automatic unwrapping is not performed when:
17729 The path expression contains
<literal>type()
</literal> or
17730 <literal>size()
</literal> methods that return the type
17731 and the number of elements in the array, respectively.
17736 The queried JSON data contain nested arrays. In this case, only
17737 the outermost array is unwrapped, while all the inner arrays
17738 remain unchanged. Thus, implicit unwrapping can only go one
17739 level down within each path evaluation step.
17746 For example, when querying the GPS data listed above, you can
17747 abstract from the fact that it stores an array of segments
17748 when using lax mode:
17750 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments.location');
</userinput>
17752 -------------------
17759 In strict mode, the specified path must exactly match the structure of
17760 the queried JSON document, so using this path
17761 expression will cause an error:
17763 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments.location');
</userinput>
17764 ERROR: jsonpath member accessor can only be applied to an object
17766 To get the same result as in lax mode, you have to explicitly unwrap the
17767 <literal>segments
</literal> array:
17769 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments[*].location');
</userinput>
17771 -------------------
17778 The unwrapping behavior of lax mode can lead to surprising results. For
17779 instance, the following query using the
<literal>.**
</literal> accessor
17780 selects every
<literal>HR
</literal> value twice:
17782 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.**.HR');
</userinput>
17790 This happens because the
<literal>.**
</literal> accessor selects both
17791 the
<literal>segments
</literal> array and each of its elements, while
17792 the
<literal>.HR
</literal> accessor automatically unwraps arrays when
17793 using lax mode. To avoid surprising results, we recommend using
17794 the
<literal>.**
</literal> accessor only in strict mode. The
17795 following query selects each
<literal>HR
</literal> value just once:
17797 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.**.HR');
</userinput>
17806 The unwrapping of arrays can also lead to unexpected results. Consider this
17807 example, which selects all the
<literal>location
</literal> arrays:
17809 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments[*].location');
</userinput>
17811 -------------------
17816 As expected it returns the full arrays. But applying a filter expression
17817 causes the arrays to be unwrapped to evaluate each item, returning only the
17818 items that match the expression:
17820 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'lax $.track.segments[*].location ?(@[*]
> 15)');
</userinput>
17827 This despite the fact that the full arrays are selected by the path
17828 expression. Use strict mode to restore selecting the arrays:
17830 <prompt>=
></prompt> <userinput>select jsonb_path_query(:'json', 'strict $.track.segments[*].location ?(@[*]
> 15)');
</userinput>
17832 -------------------
17840 <sect3 id=
"functions-sqljson-path-operators">
17841 <title>SQL/JSON Path Operators and Methods
</title>
17844 <xref linkend=
"functions-sqljson-op-table"/> shows the operators and
17845 methods available in
<type>jsonpath
</type>. Note that while the unary
17846 operators and methods can be applied to multiple values resulting from a
17847 preceding path step, the binary operators (addition etc.) can only be
17848 applied to single values. In lax mode, methods applied to an array will be
17849 executed for each value in the array. The exceptions are
17850 <literal>.type()
</literal> and
<literal>.size()
</literal>, which apply to
17854 <table id=
"functions-sqljson-op-table">
17855 <title><type>jsonpath
</type> Operators and Methods
</title>
17859 <entry role=
"func_table_entry"><para role=
"func_signature">
17873 <entry role=
"func_table_entry"><para role=
"func_signature">
17874 <replaceable>number
</replaceable> <literal>+
</literal> <replaceable>number
</replaceable>
17875 <returnvalue><replaceable>number
</replaceable></returnvalue>
17881 <literal>jsonb_path_query('[
2]', '$[
0] +
3')
</literal>
17882 <returnvalue>5</returnvalue>
17887 <entry role=
"func_table_entry"><para role=
"func_signature">
17888 <literal>+
</literal> <replaceable>number
</replaceable>
17889 <returnvalue><replaceable>number
</replaceable></returnvalue>
17892 Unary plus (no operation); unlike addition, this can iterate over
17896 <literal>jsonb_path_query_array('{
"x": [
2,
3,
4]}', '+ $.x')
</literal>
17897 <returnvalue>[
2,
3,
4]
</returnvalue>
17902 <entry role=
"func_table_entry"><para role=
"func_signature">
17903 <replaceable>number
</replaceable> <literal>-
</literal> <replaceable>number
</replaceable>
17904 <returnvalue><replaceable>number
</replaceable></returnvalue>
17910 <literal>jsonb_path_query('[
2]', '
7 - $[
0]')
</literal>
17911 <returnvalue>5</returnvalue>
17916 <entry role=
"func_table_entry"><para role=
"func_signature">
17917 <literal>-
</literal> <replaceable>number
</replaceable>
17918 <returnvalue><replaceable>number
</replaceable></returnvalue>
17921 Negation; unlike subtraction, this can iterate over
17925 <literal>jsonb_path_query_array('{
"x": [
2,
3,
4]}', '- $.x')
</literal>
17926 <returnvalue>[-
2, -
3, -
4]
</returnvalue>
17931 <entry role=
"func_table_entry"><para role=
"func_signature">
17932 <replaceable>number
</replaceable> <literal>*
</literal> <replaceable>number
</replaceable>
17933 <returnvalue><replaceable>number
</replaceable></returnvalue>
17939 <literal>jsonb_path_query('[
4]', '
2 * $[
0]')
</literal>
17940 <returnvalue>8</returnvalue>
17945 <entry role=
"func_table_entry"><para role=
"func_signature">
17946 <replaceable>number
</replaceable> <literal>/
</literal> <replaceable>number
</replaceable>
17947 <returnvalue><replaceable>number
</replaceable></returnvalue>
17953 <literal>jsonb_path_query('[
8.5]', '$[
0] /
2')
</literal>
17954 <returnvalue>4.2500000000000000</returnvalue>
17959 <entry role=
"func_table_entry"><para role=
"func_signature">
17960 <replaceable>number
</replaceable> <literal>%
</literal> <replaceable>number
</replaceable>
17961 <returnvalue><replaceable>number
</replaceable></returnvalue>
17967 <literal>jsonb_path_query('[
32]', '$[
0] %
10')
</literal>
17968 <returnvalue>2</returnvalue>
17973 <entry role=
"func_table_entry"><para role=
"func_signature">
17974 <replaceable>value
</replaceable> <literal>.
</literal> <literal>type()
</literal>
17975 <returnvalue><replaceable>string
</replaceable></returnvalue>
17978 Type of the JSON item (see
<function>json_typeof
</function>)
17981 <literal>jsonb_path_query_array('[
1,
"2", {}]', '$[*].type()')
</literal>
17982 <returnvalue>[
"number",
"string",
"object"]
</returnvalue>
17987 <entry role=
"func_table_entry"><para role=
"func_signature">
17988 <replaceable>value
</replaceable> <literal>.
</literal> <literal>size()
</literal>
17989 <returnvalue><replaceable>number
</replaceable></returnvalue>
17992 Size of the JSON item (number of array elements, or
1 if not an
17996 <literal>jsonb_path_query('{
"m": [
11,
15]}', '$.m.size()')
</literal>
17997 <returnvalue>2</returnvalue>
18002 <entry role=
"func_table_entry"><para role=
"func_signature">
18003 <replaceable>value
</replaceable> <literal>.
</literal> <literal>boolean()
</literal>
18004 <returnvalue><replaceable>boolean
</replaceable></returnvalue>
18007 Boolean value converted from a JSON boolean, number, or string
18010 <literal>jsonb_path_query_array('[
1,
"yes", false]', '$[*].boolean()')
</literal>
18011 <returnvalue>[true, true, false]
</returnvalue>
18016 <entry role=
"func_table_entry"><para role=
"func_signature">
18017 <replaceable>value
</replaceable> <literal>.
</literal> <literal>string()
</literal>
18018 <returnvalue><replaceable>string
</replaceable></returnvalue>
18021 String value converted from a JSON boolean, number, string, or
18025 <literal>jsonb_path_query_array('[
1.23,
"xyz", false]', '$[*].string()')
</literal>
18026 <returnvalue>[
"1.23",
"xyz",
"false"]
</returnvalue>
18029 <literal>jsonb_path_query('
"2023-08-15 12:34:56"', '$.timestamp().string()')
</literal>
18030 <returnvalue>"2023-08-15T12:34:56"</returnvalue>
18035 <entry role=
"func_table_entry"><para role=
"func_signature">
18036 <replaceable>value
</replaceable> <literal>.
</literal> <literal>double()
</literal>
18037 <returnvalue><replaceable>number
</replaceable></returnvalue>
18040 Approximate floating-point number converted from a JSON number or
18044 <literal>jsonb_path_query('{
"len":
"1.9"}', '$.len.double() *
2')
</literal>
18045 <returnvalue>3.8</returnvalue>
18050 <entry role=
"func_table_entry"><para role=
"func_signature">
18051 <replaceable>number
</replaceable> <literal>.
</literal> <literal>ceiling()
</literal>
18052 <returnvalue><replaceable>number
</replaceable></returnvalue>
18055 Nearest integer greater than or equal to the given number
18058 <literal>jsonb_path_query('{
"h":
1.3}', '$.h.ceiling()')
</literal>
18059 <returnvalue>2</returnvalue>
18064 <entry role=
"func_table_entry"><para role=
"func_signature">
18065 <replaceable>number
</replaceable> <literal>.
</literal> <literal>floor()
</literal>
18066 <returnvalue><replaceable>number
</replaceable></returnvalue>
18069 Nearest integer less than or equal to the given number
18072 <literal>jsonb_path_query('{
"h":
1.7}', '$.h.floor()')
</literal>
18073 <returnvalue>1</returnvalue>
18078 <entry role=
"func_table_entry"><para role=
"func_signature">
18079 <replaceable>number
</replaceable> <literal>.
</literal> <literal>abs()
</literal>
18080 <returnvalue><replaceable>number
</replaceable></returnvalue>
18083 Absolute value of the given number
18086 <literal>jsonb_path_query('{
"z": -
0.3}', '$.z.abs()')
</literal>
18087 <returnvalue>0.3</returnvalue>
18092 <entry role=
"func_table_entry"><para role=
"func_signature">
18093 <replaceable>value
</replaceable> <literal>.
</literal> <literal>bigint()
</literal>
18094 <returnvalue><replaceable>bigint
</replaceable></returnvalue>
18097 Big integer value converted from a JSON number or string
18100 <literal>jsonb_path_query('{
"len":
"9876543219"}', '$.len.bigint()')
</literal>
18101 <returnvalue>9876543219</returnvalue>
18106 <entry role=
"func_table_entry"><para role=
"func_signature">
18107 <replaceable>value
</replaceable> <literal>.
</literal> <literal>decimal( [
<replaceable>precision
</replaceable> [ ,
<replaceable>scale
</replaceable> ] ] )
</literal>
18108 <returnvalue><replaceable>decimal
</replaceable></returnvalue>
18111 Rounded decimal value converted from a JSON number or string
18112 (
<literal>precision
</literal> and
<literal>scale
</literal> must be
18116 <literal>jsonb_path_query('
1234.5678', '$.decimal(
6,
2)')
</literal>
18117 <returnvalue>1234.57</returnvalue>
18122 <entry role=
"func_table_entry"><para role=
"func_signature">
18123 <replaceable>value
</replaceable> <literal>.
</literal> <literal>integer()
</literal>
18124 <returnvalue><replaceable>integer
</replaceable></returnvalue>
18127 Integer value converted from a JSON number or string
18130 <literal>jsonb_path_query('{
"len":
"12345"}', '$.len.integer()')
</literal>
18131 <returnvalue>12345</returnvalue>
18136 <entry role=
"func_table_entry"><para role=
"func_signature">
18137 <replaceable>value
</replaceable> <literal>.
</literal> <literal>number()
</literal>
18138 <returnvalue><replaceable>numeric
</replaceable></returnvalue>
18141 Numeric value converted from a JSON number or string
18144 <literal>jsonb_path_query('{
"len":
"123.45"}', '$.len.number()')
</literal>
18145 <returnvalue>123.45</returnvalue>
18150 <entry role=
"func_table_entry"><para role=
"func_signature">
18151 <replaceable>string
</replaceable> <literal>.
</literal> <literal>datetime()
</literal>
18152 <returnvalue><replaceable>datetime_type
</replaceable></returnvalue>
18156 Date/time value converted from a string
18159 <literal>jsonb_path_query('[
"2015-8-1",
"2015-08-12"]', '$[*] ? (@.datetime()
< "2015-08-2".datetime())')
</literal>
18160 <returnvalue>"2015-8-1"</returnvalue>
18165 <entry role=
"func_table_entry"><para role=
"func_signature">
18166 <replaceable>string
</replaceable> <literal>.
</literal> <literal>datetime(
<replaceable>template
</replaceable>)
</literal>
18167 <returnvalue><replaceable>datetime_type
</replaceable></returnvalue>
18171 Date/time value converted from a string using the
18172 specified
<function>to_timestamp
</function> template
18175 <literal>jsonb_path_query_array('[
"12:30",
"18:40"]', '$[*].datetime(
"HH24:MI")')
</literal>
18176 <returnvalue>[
"12:30:00",
"18:40:00"]
</returnvalue>
18181 <entry role=
"func_table_entry"><para role=
"func_signature">
18182 <replaceable>string
</replaceable> <literal>.
</literal> <literal>date()
</literal>
18183 <returnvalue><replaceable>date
</replaceable></returnvalue>
18186 Date value converted from a string
18189 <literal>jsonb_path_query('
"2023-08-15"', '$.date()')
</literal>
18190 <returnvalue>"2023-08-15"</returnvalue>
18195 <entry role=
"func_table_entry"><para role=
"func_signature">
18196 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time()
</literal>
18197 <returnvalue><replaceable>time without time zone
</replaceable></returnvalue>
18200 Time without time zone value converted from a string
18203 <literal>jsonb_path_query('
"12:34:56"', '$.time()')
</literal>
18204 <returnvalue>"12:34:56"</returnvalue>
18209 <entry role=
"func_table_entry"><para role=
"func_signature">
18210 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time(
<replaceable>precision
</replaceable>)
</literal>
18211 <returnvalue><replaceable>time without time zone
</replaceable></returnvalue>
18214 Time without time zone value converted from a string, with fractional
18215 seconds adjusted to the given precision
18218 <literal>jsonb_path_query('
"12:34:56.789"', '$.time(
2)')
</literal>
18219 <returnvalue>"12:34:56.79"</returnvalue>
18224 <entry role=
"func_table_entry"><para role=
"func_signature">
18225 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time_tz()
</literal>
18226 <returnvalue><replaceable>time with time zone
</replaceable></returnvalue>
18229 Time with time zone value converted from a string
18232 <literal>jsonb_path_query('
"12:34:56 +05:30"', '$.time_tz()')
</literal>
18233 <returnvalue>"12:34:56+05:30"</returnvalue>
18238 <entry role=
"func_table_entry"><para role=
"func_signature">
18239 <replaceable>string
</replaceable> <literal>.
</literal> <literal>time_tz(
<replaceable>precision
</replaceable>)
</literal>
18240 <returnvalue><replaceable>time with time zone
</replaceable></returnvalue>
18243 Time with time zone value converted from a string, with fractional
18244 seconds adjusted to the given precision
18247 <literal>jsonb_path_query('
"12:34:56.789 +05:30"', '$.time_tz(
2)')
</literal>
18248 <returnvalue>"12:34:56.79+05:30"</returnvalue>
18253 <entry role=
"func_table_entry"><para role=
"func_signature">
18254 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp()
</literal>
18255 <returnvalue><replaceable>timestamp without time zone
</replaceable></returnvalue>
18258 Timestamp without time zone value converted from a string
18261 <literal>jsonb_path_query('
"2023-08-15 12:34:56"', '$.timestamp()')
</literal>
18262 <returnvalue>"2023-08-15T12:34:56"</returnvalue>
18267 <entry role=
"func_table_entry"><para role=
"func_signature">
18268 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp(
<replaceable>precision
</replaceable>)
</literal>
18269 <returnvalue><replaceable>timestamp without time zone
</replaceable></returnvalue>
18272 Timestamp without time zone value converted from a string, with
18273 fractional seconds adjusted to the given precision
18276 <literal>jsonb_path_query('
"2023-08-15 12:34:56.789"', '$.timestamp(
2)')
</literal>
18277 <returnvalue>"2023-08-15T12:34:56.79"</returnvalue>
18282 <entry role=
"func_table_entry"><para role=
"func_signature">
18283 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp_tz()
</literal>
18284 <returnvalue><replaceable>timestamp with time zone
</replaceable></returnvalue>
18287 Timestamp with time zone value converted from a string
18290 <literal>jsonb_path_query('
"2023-08-15 12:34:56 +05:30"', '$.timestamp_tz()')
</literal>
18291 <returnvalue>"2023-08-15T12:34:56+05:30"</returnvalue>
18296 <entry role=
"func_table_entry"><para role=
"func_signature">
18297 <replaceable>string
</replaceable> <literal>.
</literal> <literal>timestamp_tz(
<replaceable>precision
</replaceable>)
</literal>
18298 <returnvalue><replaceable>timestamp with time zone
</replaceable></returnvalue>
18301 Timestamp with time zone value converted from a string, with fractional
18302 seconds adjusted to the given precision
18305 <literal>jsonb_path_query('
"2023-08-15 12:34:56.789 +05:30"', '$.timestamp_tz(
2)')
</literal>
18306 <returnvalue>"2023-08-15T12:34:56.79+05:30"</returnvalue>
18311 <entry role=
"func_table_entry"><para role=
"func_signature">
18312 <replaceable>object
</replaceable> <literal>.
</literal> <literal>keyvalue()
</literal>
18313 <returnvalue><replaceable>array
</replaceable></returnvalue>
18316 The object's key-value pairs, represented as an array of objects
18317 containing three fields:
<literal>"key"</literal>,
18318 <literal>"value"</literal>, and
<literal>"id"</literal>;
18319 <literal>"id"</literal> is a unique identifier of the object the
18320 key-value pair belongs to
18323 <literal>jsonb_path_query_array('{
"x":
"20",
"y":
32}', '$.keyvalue()')
</literal>
18324 <returnvalue>[{
"id":
0,
"key":
"x",
"value":
"20"}, {
"id":
0,
"key":
"y",
"value":
32}]
</returnvalue>
18333 The result type of the
<literal>datetime()
</literal> and
18334 <literal>datetime(
<replaceable>template
</replaceable>)
</literal>
18335 methods can be
<type>date
</type>,
<type>timetz
</type>,
<type>time
</type>,
18336 <type>timestamptz
</type>, or
<type>timestamp
</type>.
18337 Both methods determine their result type dynamically.
18340 The
<literal>datetime()
</literal> method sequentially tries to
18341 match its input string to the ISO formats
18342 for
<type>date
</type>,
<type>timetz
</type>,
<type>time
</type>,
18343 <type>timestamptz
</type>, and
<type>timestamp
</type>. It stops on
18344 the first matching format and emits the corresponding data type.
18347 The
<literal>datetime(
<replaceable>template
</replaceable>)
</literal>
18348 method determines the result type according to the fields used in the
18349 provided template string.
18352 The
<literal>datetime()
</literal> and
18353 <literal>datetime(
<replaceable>template
</replaceable>)
</literal> methods
18354 use the same parsing rules as the
<literal>to_timestamp
</literal> SQL
18355 function does (see
<xref linkend=
"functions-formatting"/>), with three
18356 exceptions. First, these methods don't allow unmatched template
18357 patterns. Second, only the following separators are allowed in the
18358 template string: minus sign, period, solidus (slash), comma, apostrophe,
18359 semicolon, colon and space. Third, separators in the template string
18360 must exactly match the input string.
18363 If different date/time types need to be compared, an implicit cast is
18364 applied. A
<type>date
</type> value can be cast to
<type>timestamp
</type>
18365 or
<type>timestamptz
</type>,
<type>timestamp
</type> can be cast to
18366 <type>timestamptz
</type>, and
<type>time
</type> to
<type>timetz
</type>.
18367 However, all but the first of these conversions depend on the current
18368 <xref linkend=
"guc-timezone"/> setting, and thus can only be performed
18369 within timezone-aware
<type>jsonpath
</type> functions. Similarly, other
18370 date/time-related methods that convert strings to date/time types
18371 also do this casting, which may involve the current
18372 <xref linkend=
"guc-timezone"/> setting. Therefore, these conversions can
18373 also only be performed within timezone-aware
<type>jsonpath
</type>
18379 <xref linkend=
"functions-sqljson-filter-ex-table"/> shows the available
18380 filter expression elements.
18383 <table id=
"functions-sqljson-filter-ex-table">
18384 <title><type>jsonpath
</type> Filter Expression Elements
</title>
18388 <entry role=
"func_table_entry"><para role=
"func_signature">
18402 <entry role=
"func_table_entry"><para role=
"func_signature">
18403 <replaceable>value
</replaceable> <literal>==
</literal> <replaceable>value
</replaceable>
18404 <returnvalue>boolean
</returnvalue>
18407 Equality comparison (this, and the other comparison operators, work on
18408 all JSON scalar values)
18411 <literal>jsonb_path_query_array('[
1,
"a",
1,
3]', '$[*] ? (@ ==
1)')
</literal>
18412 <returnvalue>[
1,
1]
</returnvalue>
18415 <literal>jsonb_path_query_array('[
1,
"a",
1,
3]', '$[*] ? (@ ==
"a")')
</literal>
18416 <returnvalue>[
"a"]
</returnvalue>
18421 <entry role=
"func_table_entry"><para role=
"func_signature">
18422 <replaceable>value
</replaceable> <literal>!=
</literal> <replaceable>value
</replaceable>
18423 <returnvalue>boolean
</returnvalue>
18425 <para role=
"func_signature">
18426 <replaceable>value
</replaceable> <literal><></literal> <replaceable>value
</replaceable>
18427 <returnvalue>boolean
</returnvalue>
18430 Non-equality comparison
18433 <literal>jsonb_path_query_array('[
1,
2,
1,
3]', '$[*] ? (@ !=
1)')
</literal>
18434 <returnvalue>[
2,
3]
</returnvalue>
18437 <literal>jsonb_path_query_array('[
"a",
"b",
"c"]', '$[*] ? (@
<> "b")')
</literal>
18438 <returnvalue>[
"a",
"c"]
</returnvalue>
18443 <entry role=
"func_table_entry"><para role=
"func_signature">
18444 <replaceable>value
</replaceable> <literal><</literal> <replaceable>value
</replaceable>
18445 <returnvalue>boolean
</returnvalue>
18448 Less-than comparison
18451 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
< 2)')
</literal>
18452 <returnvalue>[
1]
</returnvalue>
18457 <entry role=
"func_table_entry"><para role=
"func_signature">
18458 <replaceable>value
</replaceable> <literal><=
</literal> <replaceable>value
</replaceable>
18459 <returnvalue>boolean
</returnvalue>
18462 Less-than-or-equal-to comparison
18465 <literal>jsonb_path_query_array('[
"a",
"b",
"c"]', '$[*] ? (@
<=
"b")')
</literal>
18466 <returnvalue>[
"a",
"b"]
</returnvalue>
18471 <entry role=
"func_table_entry"><para role=
"func_signature">
18472 <replaceable>value
</replaceable> <literal>></literal> <replaceable>value
</replaceable>
18473 <returnvalue>boolean
</returnvalue>
18476 Greater-than comparison
18479 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
> 2)')
</literal>
18480 <returnvalue>[
3]
</returnvalue>
18485 <entry role=
"func_table_entry"><para role=
"func_signature">
18486 <replaceable>value
</replaceable> <literal>>=
</literal> <replaceable>value
</replaceable>
18487 <returnvalue>boolean
</returnvalue>
18490 Greater-than-or-equal-to comparison
18493 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
>=
2)')
</literal>
18494 <returnvalue>[
2,
3]
</returnvalue>
18499 <entry role=
"func_table_entry"><para role=
"func_signature">
18500 <literal>true
</literal>
18501 <returnvalue>boolean
</returnvalue>
18504 JSON constant
<literal>true
</literal>
18507 <literal>jsonb_path_query('[{
"name":
"John",
"parent": false}, {
"name":
"Chris",
"parent": true}]', '$[*] ? (@.parent == true)')
</literal>
18508 <returnvalue>{
"name":
"Chris",
"parent": true}
</returnvalue>
18513 <entry role=
"func_table_entry"><para role=
"func_signature">
18514 <literal>false
</literal>
18515 <returnvalue>boolean
</returnvalue>
18518 JSON constant
<literal>false
</literal>
18521 <literal>jsonb_path_query('[{
"name":
"John",
"parent": false}, {
"name":
"Chris",
"parent": true}]', '$[*] ? (@.parent == false)')
</literal>
18522 <returnvalue>{
"name":
"John",
"parent": false}
</returnvalue>
18527 <entry role=
"func_table_entry"><para role=
"func_signature">
18528 <literal>null
</literal>
18529 <returnvalue><replaceable>value
</replaceable></returnvalue>
18532 JSON constant
<literal>null
</literal> (note that, unlike in SQL,
18533 comparison to
<literal>null
</literal> works normally)
18536 <literal>jsonb_path_query('[{
"name":
"Mary",
"job": null}, {
"name":
"Michael",
"job":
"driver"}]', '$[*] ? (@.job == null) .name')
</literal>
18537 <returnvalue>"Mary"</returnvalue>
18542 <entry role=
"func_table_entry"><para role=
"func_signature">
18543 <replaceable>boolean
</replaceable> <literal>&&</literal> <replaceable>boolean
</replaceable>
18544 <returnvalue>boolean
</returnvalue>
18550 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (@
> 1 && @
< 5)')
</literal>
18551 <returnvalue>3</returnvalue>
18556 <entry role=
"func_table_entry"><para role=
"func_signature">
18557 <replaceable>boolean
</replaceable> <literal>||
</literal> <replaceable>boolean
</replaceable>
18558 <returnvalue>boolean
</returnvalue>
18564 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (@
< 1 || @
> 5)')
</literal>
18565 <returnvalue>7</returnvalue>
18570 <entry role=
"func_table_entry"><para role=
"func_signature">
18571 <literal>!
</literal> <replaceable>boolean
</replaceable>
18572 <returnvalue>boolean
</returnvalue>
18578 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (!(@
< 5))')
</literal>
18579 <returnvalue>7</returnvalue>
18584 <entry role=
"func_table_entry"><para role=
"func_signature">
18585 <replaceable>boolean
</replaceable> <literal>is unknown
</literal>
18586 <returnvalue>boolean
</returnvalue>
18589 Tests whether a Boolean condition is
<literal>unknown
</literal>.
18592 <literal>jsonb_path_query('[-
1,
2,
7,
"foo"]', '$[*] ? ((@
> 0) is unknown)')
</literal>
18593 <returnvalue>"foo"</returnvalue>
18598 <entry role=
"func_table_entry"><para role=
"func_signature">
18599 <replaceable>string
</replaceable> <literal>like_regex
</literal> <replaceable>string
</replaceable> <optional> <literal>flag
</literal> <replaceable>string
</replaceable> </optional>
18600 <returnvalue>boolean
</returnvalue>
18603 Tests whether the first operand matches the regular expression
18604 given by the second operand, optionally with modifications
18605 described by a string of
<literal>flag
</literal> characters (see
18606 <xref linkend=
"jsonpath-regular-expressions"/>).
18609 <literal>jsonb_path_query_array('[
"abc",
"abd",
"aBdC",
"abdacb",
"babc"]', '$[*] ? (@ like_regex
"^ab.*c")')
</literal>
18610 <returnvalue>[
"abc",
"abdacb"]
</returnvalue>
18613 <literal>jsonb_path_query_array('[
"abc",
"abd",
"aBdC",
"abdacb",
"babc"]', '$[*] ? (@ like_regex
"^ab.*c" flag
"i")')
</literal>
18614 <returnvalue>[
"abc",
"aBdC",
"abdacb"]
</returnvalue>
18619 <entry role=
"func_table_entry"><para role=
"func_signature">
18620 <replaceable>string
</replaceable> <literal>starts with
</literal> <replaceable>string
</replaceable>
18621 <returnvalue>boolean
</returnvalue>
18624 Tests whether the second operand is an initial substring of the first
18628 <literal>jsonb_path_query('[
"John Smith",
"Mary Stone",
"Bob Johnson"]', '$[*] ? (@ starts with
"John")')
</literal>
18629 <returnvalue>"John Smith"</returnvalue>
18634 <entry role=
"func_table_entry"><para role=
"func_signature">
18635 <literal>exists
</literal> <literal>(
</literal> <replaceable>path_expression
</replaceable> <literal>)
</literal>
18636 <returnvalue>boolean
</returnvalue>
18639 Tests whether a path expression matches at least one SQL/JSON item.
18640 Returns
<literal>unknown
</literal> if the path expression would result
18641 in an error; the second example uses this to avoid a no-such-key error
18645 <literal>jsonb_path_query('{
"x": [
1,
2],
"y": [
2,
4]}', 'strict $.* ? (exists (@ ? (@[*]
> 2)))')
</literal>
18646 <returnvalue>[
2,
4]
</returnvalue>
18649 <literal>jsonb_path_query_array('{
"value":
41}', 'strict $ ? (exists (@.name)) .name')
</literal>
18650 <returnvalue>[]
</returnvalue>
18659 <sect3 id=
"jsonpath-regular-expressions">
18660 <title>SQL/JSON Regular Expressions
</title>
18662 <indexterm zone=
"jsonpath-regular-expressions">
18663 <primary><literal>LIKE_REGEX
</literal></primary>
18664 <secondary>in SQL/JSON
</secondary>
18668 SQL/JSON path expressions allow matching text to a regular expression
18669 with the
<literal>like_regex
</literal> filter. For example, the
18670 following SQL/JSON path query would case-insensitively match all
18671 strings in an array that start with an English vowel:
18673 $[*] ? (@ like_regex
"^[aeiou]" flag
"i")
18678 The optional
<literal>flag
</literal> string may include one or more of
18680 <literal>i
</literal> for case-insensitive match,
18681 <literal>m
</literal> to allow
<literal>^
</literal>
18682 and
<literal>$
</literal> to match at newlines,
18683 <literal>s
</literal> to allow
<literal>.
</literal> to match a newline,
18684 and
<literal>q
</literal> to quote the whole pattern (reducing the
18685 behavior to a simple substring match).
18689 The SQL/JSON standard borrows its definition for regular expressions
18690 from the
<literal>LIKE_REGEX
</literal> operator, which in turn uses the
18691 XQuery standard. PostgreSQL does not currently support the
18692 <literal>LIKE_REGEX
</literal> operator. Therefore,
18693 the
<literal>like_regex
</literal> filter is implemented using the
18694 POSIX regular expression engine described in
18695 <xref linkend=
"functions-posix-regexp"/>. This leads to various minor
18696 discrepancies from standard SQL/JSON behavior, which are cataloged in
18697 <xref linkend=
"posix-vs-xquery"/>.
18698 Note, however, that the flag-letter incompatibilities described there
18699 do not apply to SQL/JSON, as it translates the XQuery flag letters to
18700 match what the POSIX engine expects.
18704 Keep in mind that the pattern argument of
<literal>like_regex
</literal>
18705 is a JSON path string literal, written according to the rules given in
18706 <xref linkend=
"datatype-jsonpath"/>. This means in particular that any
18707 backslashes you want to use in the regular expression must be doubled.
18708 For example, to match string values of the root document that contain
18711 $.* ? (@ like_regex
"^\\d+$")
18717 <sect2 id=
"sqljson-query-functions">
18718 <title>SQL/JSON Query Functions
</title>
18720 SQL/JSON functions
<literal>JSON_EXISTS()
</literal>,
18721 <literal>JSON_QUERY()
</literal>, and
<literal>JSON_VALUE()
</literal>
18722 described in
<xref linkend=
"functions-sqljson-querying"/> can be used
18723 to query JSON documents. Each of these functions apply a
18724 <replaceable>path_expression
</replaceable> (an SQL/JSON path query) to a
18725 <replaceable>context_item
</replaceable> (the document). See
18726 <xref linkend=
"functions-sqljson-path"/> for more details on what
18727 the
<replaceable>path_expression
</replaceable> can contain. The
18728 <replaceable>path_expression
</replaceable> can also reference variables,
18729 whose values are specified with their respective names in the
18730 <literal>PASSING
</literal> clause that is supported by each function.
18731 <replaceable>context_item
</replaceable> can be a
<type>jsonb
</type> value
18732 or a character string that can be successfully cast to
<type>jsonb
</type>.
18735 <table id=
"functions-sqljson-querying">
18736 <title>SQL/JSON Query Functions
</title>
18740 <entry role=
"func_table_entry"><para role=
"func_signature">
18753 <entry role=
"func_table_entry"><para role=
"func_signature">
18754 <indexterm><primary>json_exists
</primary></indexterm>
18756 <function>JSON_EXISTS
</function> (
18757 <replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable>
18758 <optional> <literal>PASSING
</literal> {
<replaceable>value
</replaceable> <literal>AS
</literal> <replaceable>varname
</replaceable> }
<optional>, ...
</optional></optional>
18759 <optional>{
<literal>TRUE
</literal> |
<literal>FALSE
</literal> |
<literal> UNKNOWN
</literal> |
<literal>ERROR
</literal> }
<literal>ON ERROR
</literal> </optional>)
<returnvalue>boolean
</returnvalue>
18765 Returns true if the SQL/JSON
<replaceable>path_expression
</replaceable>
18766 applied to the
<replaceable>context_item
</replaceable> yields any
18767 items, false otherwise.
18772 The
<literal>ON ERROR
</literal> clause specifies the behavior if
18773 an error occurs during
<replaceable>path_expression
</replaceable>
18774 evaluation. Specifying
<literal>ERROR
</literal> will cause an error to
18775 be thrown with the appropriate message. Other options include
18776 returning
<type>boolean
</type> values
<literal>FALSE
</literal> or
18777 <literal>TRUE
</literal> or the value
<literal>UNKNOWN
</literal> which
18778 is actually an SQL NULL. The default when no
<literal>ON ERROR
</literal>
18779 clause is specified is to return the
<type>boolean
</type> value
18780 <literal>FALSE
</literal>.
18788 <literal>JSON_EXISTS(jsonb '{
"key1": [
1,
2,
3]}', 'strict $.key1[*] ? (@
> $x)' PASSING
2 AS x)
</literal>
18789 <returnvalue>t
</returnvalue>
18792 <literal>JSON_EXISTS(jsonb '{
"a": [
1,
2,
3]}', 'lax $.a[
5]' ERROR ON ERROR)
</literal>
18793 <returnvalue>f
</returnvalue>
18796 <literal>JSON_EXISTS(jsonb '{
"a": [
1,
2,
3]}', 'strict $.a[
5]' ERROR ON ERROR)
</literal>
18797 <returnvalue></returnvalue>
18799 ERROR: jsonpath array subscript is out of bounds
18804 <entry role=
"func_table_entry"><para role=
"func_signature">
18805 <indexterm><primary>json_query
</primary></indexterm>
18807 <function>JSON_QUERY
</function> (
18808 <replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable>
18809 <optional> <literal>PASSING
</literal> {
<replaceable>value
</replaceable> <literal>AS
</literal> <replaceable>varname
</replaceable> }
<optional>, ...
</optional></optional>
18810 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>
18811 <optional> {
<literal>WITHOUT
</literal> |
<literal>WITH
</literal> {
<literal>CONDITIONAL
</literal> |
<optional><literal>UNCONDITIONAL
</literal></optional> } }
<optional> <literal>ARRAY
</literal> </optional> <literal>WRAPPER
</literal> </optional>
18812 <optional> {
<literal>KEEP
</literal> |
<literal>OMIT
</literal> }
<literal>QUOTES
</literal> <optional> <literal>ON SCALAR STRING
</literal> </optional> </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 EMPTY
</literal> </optional>
18814 <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>
18820 Returns the result of applying the SQL/JSON
18821 <replaceable>path_expression
</replaceable> to the
18822 <replaceable>context_item
</replaceable>.
18827 By default, the result is returned as a value of type
<type>jsonb
</type>,
18828 though the
<literal>RETURNING
</literal> clause can be used to return
18829 as some other type to which it can be successfully coerced.
18834 If the path expression may return multiple values, it might be necessary
18835 to wrap those values using the
<literal>WITH WRAPPER
</literal> clause to
18836 make it a valid JSON string, because the default behavior is to not wrap
18837 them, as if
<literal>WITHOUT WRAPPER
</literal> were specified. The
18838 <literal>WITH WRAPPER
</literal> clause is by default taken to mean
18839 <literal>WITH UNCONDITIONAL WRAPPER
</literal>, which means that even a
18840 single result value will be wrapped. To apply the wrapper only when
18841 multiple values are present, specify
<literal>WITH CONDITIONAL WRAPPER
</literal>.
18842 Getting multiple values in result will be treated as an error if
18843 <literal>WITHOUT WRAPPER
</literal> is specified.
18848 If the result is a scalar string, by default, the returned value will
18849 be surrounded by quotes, making it a valid JSON value. It can be made
18850 explicit by specifying
<literal>KEEP QUOTES
</literal>. Conversely,
18851 quotes can be omitted by specifying
<literal>OMIT QUOTES
</literal>.
18852 To ensure that the result is a valid JSON value,
<literal>OMIT QUOTES
</literal>
18853 cannot be specified when
<literal>WITH WRAPPER
</literal> is also
18859 The
<literal>ON EMPTY
</literal> clause specifies the behavior if
18860 evaluating
<replaceable>path_expression
</replaceable> yields an empty
18861 set. The
<literal>ON ERROR
</literal> clause specifies the behavior
18862 if an error occurs when evaluating
<replaceable>path_expression
</replaceable>,
18863 when coercing the result value to the
<literal>RETURNING
</literal> type,
18864 or when evaluating the
<literal>ON EMPTY
</literal> expression if the
18865 <replaceable>path_expression
</replaceable> evaluation returns an empty
18871 For both
<literal>ON EMPTY
</literal> and
<literal>ON ERROR
</literal>,
18872 specifying
<literal>ERROR
</literal> will cause an error to be thrown with
18873 the appropriate message. Other options include returning an SQL NULL, an
18874 empty array (
<literal>EMPTY
<optional>ARRAY
</optional></literal>),
18875 an empty object (
<literal>EMPTY OBJECT
</literal>), or a user-specified
18876 expression (
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable>)
18877 that can be coerced to jsonb or the type specified in
<literal>RETURNING
</literal>.
18878 The default when
<literal>ON EMPTY
</literal> or
<literal>ON ERROR
</literal>
18879 is not specified is to return an SQL NULL value.
18887 <literal>JSON_QUERY(jsonb '[
1,[
2,
3],null]', 'lax $[*][$off]' PASSING
1 AS off WITH CONDITIONAL WRAPPER)
</literal>
18888 <returnvalue>3</returnvalue>
18891 <literal>JSON_QUERY(jsonb '{
"a":
"[1, 2]"}', 'lax $.a' OMIT QUOTES)
</literal>
18892 <returnvalue>[
1,
2]
</returnvalue>
18895 <literal>JSON_QUERY(jsonb '{
"a":
"[1, 2]"}', 'lax $.a' RETURNING int[] OMIT QUOTES ERROR ON ERROR)
</literal>
18896 <returnvalue></returnvalue>
18898 ERROR: malformed array literal:
"[1, 2]"
18899 DETAIL: Missing
"]" after array dimensions.
18905 <entry role=
"func_table_entry"><para role=
"func_signature">
18906 <indexterm><primary>json_value
</primary></indexterm>
18908 <function>JSON_VALUE
</function> (
18909 <replaceable>context_item
</replaceable>,
<replaceable>path_expression
</replaceable>
18910 <optional> <literal>PASSING
</literal> {
<replaceable>value
</replaceable> <literal>AS
</literal> <replaceable>varname
</replaceable> }
<optional>, ...
</optional></optional>
18911 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> </optional>
18912 <optional> {
<literal>ERROR
</literal> |
<literal>NULL
</literal> |
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable> }
<literal>ON EMPTY
</literal> </optional>
18913 <optional> {
<literal>ERROR
</literal> |
<literal>NULL
</literal> |
<literal>DEFAULT
</literal> <replaceable>expression
</replaceable> }
<literal>ON ERROR
</literal> </optional>)
<returnvalue>text
</returnvalue>
18919 Returns the result of applying the SQL/JSON
18920 <replaceable>path_expression
</replaceable> to the
18921 <replaceable>context_item
</replaceable>.
18926 Only use
<function>JSON_VALUE()
</function> if the extracted value is
18927 expected to be a single
<acronym>SQL/JSON
</acronym> scalar item;
18928 getting multiple values will be treated as an error. If you expect that
18929 extracted value might be an object or an array, use the
18930 <function>JSON_QUERY
</function> function instead.
18935 By default, the result, which must be a single scalar value, is
18936 returned as a value of type
<type>text
</type>, though the
18937 <literal>RETURNING
</literal> clause can be used to return as some
18938 other type to which it can be successfully coerced.
18943 The
<literal>ON ERROR
</literal> and
<literal>ON EMPTY
</literal>
18944 clauses have similar semantics as mentioned in the description of
18945 <function>JSON_QUERY
</function>, except the set of values returned in
18946 lieu of throwing an error is different.
18951 Note that scalar strings returned by
<function>JSON_VALUE
</function>
18952 always have their quotes removed, equivalent to specifying
18953 <literal>OMIT QUOTES
</literal> in
<function>JSON_QUERY
</function>.
18961 <literal>JSON_VALUE(jsonb '
"123.45"', '$' RETURNING float)
</literal>
18962 <returnvalue>123.45</returnvalue>
18965 <literal>JSON_VALUE(jsonb '
"03:04 2015-02-01"', '$.datetime(
"HH24:MI YYYY-MM-DD")' RETURNING date)
</literal>
18966 <returnvalue>2015-
02-
01</returnvalue>
18969 <literal>JSON_VALUE(jsonb '[
1,
2]', 'strict $[$off]' PASSING
1 as off)
</literal>
18970 <returnvalue>2</returnvalue>
18973 <literal>JSON_VALUE(jsonb '[
1,
2]', 'strict $[*]' DEFAULT
9 ON ERROR)
</literal>
18974 <returnvalue>9</returnvalue>
18983 The
<replaceable>context_item
</replaceable> expression is converted to
18984 <type>jsonb
</type> by an implicit cast if the expression is not already of
18985 type
<type>jsonb
</type>. Note, however, that any parsing errors that occur
18986 during that conversion are thrown unconditionally, that is, are not
18987 handled according to the (specified or implicit)
<literal>ON ERROR
</literal>
18993 <function>JSON_VALUE()
</function> returns an SQL NULL if
18994 <replaceable>path_expression
</replaceable> returns a JSON
18995 <literal>null
</literal>, whereas
<function>JSON_QUERY()
</function> returns
18996 the JSON
<literal>null
</literal> as is.
19001 <sect2 id=
"functions-sqljson-table">
19002 <title>JSON_TABLE
</title>
19004 <primary>json_table
</primary>
19008 <function>JSON_TABLE
</function> is an SQL/JSON function which
19009 queries
<acronym>JSON
</acronym> data
19010 and presents the results as a relational view, which can be accessed as a
19011 regular SQL table. You can use
<function>JSON_TABLE
</function> inside
19012 the
<literal>FROM
</literal> clause of a
<literal>SELECT
</literal>,
19013 <literal>UPDATE
</literal>, or
<literal>DELETE
</literal> and as data source
19014 in a
<literal>MERGE
</literal> statement.
19018 Taking JSON data as input,
<function>JSON_TABLE
</function> uses a JSON path
19019 expression to extract a part of the provided data to use as a
19020 <firstterm>row pattern
</firstterm> for the constructed view. Each SQL/JSON
19021 value given by the row pattern serves as source for a separate row in the
19026 To split the row pattern into columns,
<function>JSON_TABLE
</function>
19027 provides the
<literal>COLUMNS
</literal> clause that defines the
19028 schema of the created view. For each column, a separate JSON path expression
19029 can be specified to be evaluated against the row pattern to get an SQL/JSON
19030 value that will become the value for the specified column in a given output
19035 JSON data stored at a nested level of the row pattern can be extracted using
19036 the
<literal>NESTED PATH
</literal> clause. Each
19037 <literal>NESTED PATH
</literal> clause can be used to generate one or more
19038 columns using the data from a nested level of the row pattern. Those
19039 columns can be specified using a
<literal>COLUMNS
</literal> clause that
19040 looks similar to the top-level COLUMNS clause. Rows constructed from
19041 NESTED COLUMNS are called
<firstterm>child rows
</firstterm> and are joined
19042 against the row constructed from the columns specified in the parent
19043 <literal>COLUMNS
</literal> clause to get the row in the final view. Child
19044 columns themselves may contain a
<literal>NESTED PATH
</literal>
19045 specification thus allowing to extract data located at arbitrary nesting
19046 levels. Columns produced by multiple
<literal>NESTED PATH
</literal>s at the
19047 same level are considered to be
<firstterm>siblings
</firstterm> of each
19048 other and their rows after joining with the parent row are combined using
19053 The rows produced by
<function>JSON_TABLE
</function> are laterally
19054 joined to the row that generated them, so you do not have to explicitly join
19055 the constructed view with the original table holding
<acronym>JSON
</acronym>
19065 <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>
19066 COLUMNS (
<replaceable class=
"parameter">json_table_column
</replaceable> <optional>, ...
</optional> )
19067 <optional> {
<literal>ERROR
</literal> |
<literal>EMPTY
</literal> <optional>ARRAY
</optional>}
<literal>ON ERROR
</literal> </optional>
19071 where
<replaceable class=
"parameter">json_table_column
</replaceable> is:
19073 <replaceable>name
</replaceable> FOR ORDINALITY
19074 |
<replaceable>name
</replaceable> <replaceable>type
</replaceable>
19075 <optional> FORMAT JSON
<optional>ENCODING
<literal>UTF8
</literal></optional></optional>
19076 <optional> PATH
<replaceable>path_expression
</replaceable> </optional>
19077 <optional> { WITHOUT | WITH { CONDITIONAL |
<optional>UNCONDITIONAL
</optional> } }
<optional> ARRAY
</optional> WRAPPER
</optional>
19078 <optional> { KEEP | OMIT } QUOTES
<optional> ON SCALAR STRING
</optional> </optional>
19079 <optional> { ERROR | NULL | EMPTY {
<optional>ARRAY
</optional> | OBJECT } | DEFAULT
<replaceable>expression
</replaceable> } ON EMPTY
</optional>
19080 <optional> { ERROR | NULL | EMPTY {
<optional>ARRAY
</optional> | OBJECT } | DEFAULT
<replaceable>expression
</replaceable> } ON ERROR
</optional>
19081 |
<replaceable>name
</replaceable> <replaceable>type
</replaceable> EXISTS
<optional> PATH
<replaceable>path_expression
</replaceable> </optional>
19082 <optional> { ERROR | TRUE | FALSE | UNKNOWN } ON ERROR
</optional>
19083 | NESTED
<optional> PATH
</optional> <replaceable>path_expression
</replaceable> <optional> AS
<replaceable>json_path_name
</replaceable> </optional> COLUMNS (
<replaceable>json_table_column
</replaceable> <optional>, ...
</optional> )
19087 Each syntax element is described below in more detail.
19093 <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>
19097 The
<replaceable>context_item
</replaceable> specifies the input document
19098 to query, the
<replaceable>path_expression
</replaceable> is an SQL/JSON
19099 path expression defining the query, and
<replaceable>json_path_name
</replaceable>
19100 is an optional name for the
<replaceable>path_expression
</replaceable>.
19101 The optional
<literal>PASSING
</literal> clause provides data values for
19102 the variables mentioned in the
<replaceable>path_expression
</replaceable>.
19103 The result of the input data evaluation using the aforementioned elements
19104 is called the
<firstterm>row pattern
</firstterm>, which is used as the
19105 source for row values in the constructed view.
19112 <literal>COLUMNS
</literal> (
<replaceable>json_table_column
</replaceable> <optional>, ...
</optional> )
19117 The
<literal>COLUMNS
</literal> clause defining the schema of the
19118 constructed view. In this clause, you can specify each column to be
19119 filled with an SQL/JSON value obtained by applying a JSON path expression
19120 against the row pattern.
<replaceable>json_table_column
</replaceable> has
19121 the following variants:
19127 <replaceable>name
</replaceable> <literal>FOR ORDINALITY
</literal>
19131 Adds an ordinality column that provides sequential row numbering starting
19132 from
1. Each
<literal>NESTED PATH
</literal> (see below) gets its own
19133 counter for any nested ordinality columns.
19140 <literal><replaceable>name
</replaceable> <replaceable>type
</replaceable>
19141 <optional><literal>FORMAT JSON
</literal> <optional>ENCODING
<literal>UTF8
</literal></optional></optional>
19142 <optional> <literal>PATH
</literal> <replaceable>path_expression
</replaceable> </optional></literal>
19146 Inserts an SQL/JSON value obtained by applying
19147 <replaceable>path_expression
</replaceable> against the row pattern into
19148 the view's output row after coercing it to specified
19149 <replaceable>type
</replaceable>.
19152 Specifying
<literal>FORMAT JSON
</literal> makes it explicit that you
19153 expect the value to be a valid
<type>json
</type> object. It only
19154 makes sense to specify
<literal>FORMAT JSON
</literal> if
19155 <replaceable>type
</replaceable> is one of
<type>bpchar
</type>,
19156 <type>bytea
</type>,
<type>character varying
</type>,
<type>name
</type>,
19157 <type>json
</type>,
<type>jsonb
</type>,
<type>text
</type>, or a domain over
19161 Optionally, you can specify
<literal>WRAPPER
</literal> and
19162 <literal>QUOTES
</literal> clauses to format the output. Note that
19163 specifying
<literal>OMIT QUOTES
</literal> overrides
19164 <literal>FORMAT JSON
</literal> if also specified, because unquoted
19165 literals do not constitute valid
<type>json
</type> values.
19168 Optionally, you can use
<literal>ON EMPTY
</literal> and
19169 <literal>ON ERROR
</literal> clauses to specify whether to throw the error
19170 or return the specified value when the result of JSON path evaluation is
19171 empty and when an error occurs during JSON path evaluation or when
19172 coercing the SQL/JSON value to the specified type, respectively. The
19173 default for both is to return a
<literal>NULL
</literal> value.
19177 This clause is internally turned into and has the same semantics as
19178 <function>JSON_VALUE
</function> or
<function>JSON_QUERY
</function>.
19179 The latter if the specified type is not a scalar type or if either of
19180 <literal>FORMAT JSON
</literal>,
<literal>WRAPPER
</literal>, or
19181 <literal>QUOTES
</literal> clause is present.
19189 <replaceable>name
</replaceable> <replaceable>type
</replaceable>
19190 <literal>EXISTS
</literal> <optional> <literal>PATH
</literal> <replaceable>path_expression
</replaceable> </optional>
19194 Inserts a boolean value obtained by applying
19195 <replaceable>path_expression
</replaceable> against the row pattern
19196 into the view's output row after coercing it to specified
19197 <replaceable>type
</replaceable>.
19200 The value corresponds to whether applying the
<literal>PATH
</literal>
19201 expression to the row pattern yields any values.
19204 The specified
<replaceable>type
</replaceable> should have a cast from the
19205 <type>boolean
</type> type.
19208 Optionally, you can use
<literal>ON ERROR
</literal> to specify whether to
19209 throw the error or return the specified value when an error occurs during
19210 JSON path evaluation or when coercing SQL/JSON value to the specified
19211 type. The default is to return a boolean value
19212 <literal>FALSE
</literal>.
19216 This clause is internally turned into and has the same semantics as
19217 <function>JSON_EXISTS
</function>.
19225 <literal>NESTED
<optional> PATH
</optional></literal> <replaceable>path_expression
</replaceable> <optional> <literal>AS
</literal> <replaceable>json_path_name
</replaceable> </optional>
19226 <literal>COLUMNS
</literal> (
<replaceable>json_table_column
</replaceable> <optional>, ...
</optional> )
19231 Extracts SQL/JSON values from nested levels of the row pattern,
19232 generates one or more columns as defined by the
<literal>COLUMNS
</literal>
19233 subclause, and inserts the extracted SQL/JSON values into those
19234 columns. The
<replaceable>json_table_column
</replaceable>
19235 expression in the
<literal>COLUMNS
</literal> subclause uses the same
19236 syntax as in the parent
<literal>COLUMNS
</literal> clause.
19240 The
<literal>NESTED PATH
</literal> syntax is recursive,
19241 so you can go down multiple nested levels by specifying several
19242 <literal>NESTED PATH
</literal> subclauses within each other.
19243 It allows to unnest the hierarchy of JSON objects and arrays
19244 in a single function invocation rather than chaining several
19245 <function>JSON_TABLE
</function> expressions in an SQL statement.
19253 In each variant of
<replaceable>json_table_column
</replaceable> described
19254 above, if the
<literal>PATH
</literal> clause is omitted, path expression
19255 <literal>$.
<replaceable>name
</replaceable></literal> is used, where
19256 <replaceable>name
</replaceable> is the provided column name.
19265 <literal>AS
</literal> <replaceable>json_path_name
</replaceable>
19270 The optional
<replaceable>json_path_name
</replaceable> serves as an
19271 identifier of the provided
<replaceable>path_expression
</replaceable>.
19272 The name must be unique and distinct from the column names.
19279 {
<literal>ERROR
</literal> |
<literal>EMPTY
</literal> }
<literal>ON ERROR
</literal>
19284 The optional
<literal>ON ERROR
</literal> can be used to specify how to
19285 handle errors when evaluating the top-level
19286 <replaceable>path_expression
</replaceable>. Use
<literal>ERROR
</literal>
19287 if you want the errors to be thrown and
<literal>EMPTY
</literal> to
19288 return an empty table, that is, a table containing
0 rows. Note that
19289 this clause does not affect the errors that occur when evaluating
19290 columns, for which the behavior depends on whether the
19291 <literal>ON ERROR
</literal> clause is specified against a given column.
19297 <para>Examples
</para>
19300 In the examples that follow, the following table containing JSON data
19304 CREATE TABLE my_films ( js jsonb );
19306 INSERT INTO my_films VALUES (
19308 {
"kind" :
"comedy",
"films" : [
19309 {
"title" :
"Bananas",
19310 "director" :
"Woody Allen"},
19311 {
"title" :
"The Dinner Game",
19312 "director" :
"Francis Veber" } ] },
19313 {
"kind" :
"horror",
"films" : [
19314 {
"title" :
"Psycho",
19315 "director" :
"Alfred Hitchcock" } ] },
19316 {
"kind" :
"thriller",
"films" : [
19317 {
"title" :
"Vertigo",
19318 "director" :
"Alfred Hitchcock" } ] },
19319 {
"kind" :
"drama",
"films" : [
19320 {
"title" :
"Yojimbo",
19321 "director" :
"Akira Kurosawa" } ] }
19327 The following query shows how to use
<function>JSON_TABLE
</function> to
19328 turn the JSON objects in the
<structname>my_films
</structname> table
19329 to a view containing columns for the keys
<literal>kind
</literal>,
19330 <literal>title
</literal>, and
<literal>director
</literal> contained in
19331 the original JSON along with an ordinality column:
19336 JSON_TABLE (js, '$.favorites[*]' COLUMNS (
19338 kind text PATH '$.kind',
19339 title text PATH '$.films[*].title' WITH WRAPPER,
19340 director text PATH '$.films[*].director' WITH WRAPPER)) AS jt;
19344 id | kind | title | director
19345 ----+----------+--------------------------------+----------------------------------
19346 1 | comedy | [
"Bananas",
"The Dinner Game"] | [
"Woody Allen",
"Francis Veber"]
19347 2 | horror | [
"Psycho"] | [
"Alfred Hitchcock"]
19348 3 | thriller | [
"Vertigo"] | [
"Alfred Hitchcock"]
19349 4 | drama | [
"Yojimbo"] | [
"Akira Kurosawa"]
19355 The following is a modified version of the above query to show the
19356 usage of
<literal>PASSING
</literal> arguments in the filter specified in
19357 the top-level JSON path expression and the various options for the
19358 individual columns:
19363 JSON_TABLE (js, '$.favorites[*] ? (@.films[*].director == $filter)'
19364 PASSING 'Alfred Hitchcock' AS filter, 'Vertigo' AS filter2
19367 kind text PATH '$.kind',
19368 title text FORMAT JSON PATH '$.films[*].title' OMIT QUOTES,
19369 director text PATH '$.films[*].director' KEEP QUOTES)) AS jt;
19373 id | kind | title | director
19374 ----+----------+---------+--------------------
19375 1 | horror | Psycho |
"Alfred Hitchcock"
19376 2 | thriller | Vertigo |
"Alfred Hitchcock"
19382 The following is a modified version of the above query to show the usage
19383 of
<literal>NESTED PATH
</literal> for populating title and director
19384 columns, illustrating how they are joined to the parent columns id and
19390 JSON_TABLE ( js, '$.favorites[*] ? (@.films[*].director == $filter)'
19391 PASSING 'Alfred Hitchcock' AS filter
19394 kind text PATH '$.kind',
19395 NESTED PATH '$.films[*]' COLUMNS (
19396 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
19397 director text PATH '$.director' KEEP QUOTES))) AS jt;
19401 id | kind | title | director
19402 ----+----------+---------+--------------------
19403 1 | horror | Psycho |
"Alfred Hitchcock"
19404 2 | thriller | Vertigo |
"Alfred Hitchcock"
19411 The following is the same query but without the filter in the root
19417 JSON_TABLE ( js, '$.favorites[*]'
19420 kind text PATH '$.kind',
19421 NESTED PATH '$.films[*]' COLUMNS (
19422 title text FORMAT JSON PATH '$.title' OMIT QUOTES,
19423 director text PATH '$.director' KEEP QUOTES))) AS jt;
19427 id | kind | title | director
19428 ----+----------+-----------------+--------------------
19429 1 | comedy | Bananas |
"Woody Allen"
19430 1 | comedy | The Dinner Game |
"Francis Veber"
19431 2 | horror | Psycho |
"Alfred Hitchcock"
19432 3 | thriller | Vertigo |
"Alfred Hitchcock"
19433 4 | drama | Yojimbo |
"Akira Kurosawa"
19440 The following shows another query using a different
<type>JSON
</type>
19441 object as input. It shows the UNION
"sibling join" between
19442 <literal>NESTED
</literal> paths
<literal>$.movies[*]
</literal> and
19443 <literal>$.books[*]
</literal> and also the usage of
19444 <literal>FOR ORDINALITY
</literal> column at
<literal>NESTED
</literal>
19445 levels (columns
<literal>movie_id
</literal>,
<literal>book_id
</literal>,
19446 and
<literal>author_id
</literal>):
19449 SELECT * FROM JSON_TABLE (
19452 [{
"name":
"One",
"director":
"John Doe"},
19453 {
"name":
"Two",
"director":
"Don Joe"}],
19455 [{
"name":
"Mystery",
"authors": [{
"name":
"Brown Dan"}]},
19456 {
"name":
"Wonder",
"authors": [{
"name":
"Jun Murakami"}, {
"name":
"Craig Doe"}]}]
19457 }}'::json, '$.favorites[*]'
19459 user_id FOR ORDINALITY,
19460 NESTED '$.movies[*]'
19462 movie_id FOR ORDINALITY,
19463 mname text PATH '$.name',
19465 NESTED '$.books[*]'
19467 book_id FOR ORDINALITY,
19468 bname text PATH '$.name',
19469 NESTED '$.authors[*]'
19471 author_id FOR ORDINALITY,
19472 author_name text PATH '$.name'))));
19476 user_id | movie_id | mname | director | book_id | bname | author_id | author_name
19477 ---------+----------+-------+----------+---------+---------+-----------+--------------
19478 1 |
1 | One | John Doe | | | |
19479 1 |
2 | Two | Don Joe | | | |
19480 1 | | | |
1 | Mystery |
1 | Brown Dan
19481 1 | | | |
2 | Wonder |
1 | Jun Murakami
19482 1 | | | |
2 | Wonder |
2 | Craig Doe
19490 <sect1 id=
"functions-sequence">
19491 <title>Sequence Manipulation Functions
</title>
19494 <primary>sequence
</primary>
19498 This section describes functions for operating on
<firstterm>sequence
19499 objects
</firstterm>, also called sequence generators or just sequences.
19500 Sequence objects are special single-row tables created with
<xref
19501 linkend=
"sql-createsequence"/>.
19502 Sequence objects are commonly used to generate unique identifiers
19503 for rows of a table. The sequence functions, listed in
<xref
19504 linkend=
"functions-sequence-table"/>, provide simple, multiuser-safe
19505 methods for obtaining successive sequence values from sequence
19509 <table id=
"functions-sequence-table">
19510 <title>Sequence Functions
</title>
19514 <entry role=
"func_table_entry"><para role=
"func_signature">
19525 <entry role=
"func_table_entry"><para role=
"func_signature">
19527 <primary>nextval
</primary>
19529 <function>nextval
</function> (
<type>regclass
</type> )
19530 <returnvalue>bigint
</returnvalue>
19533 Advances the sequence object to its next value and returns that value.
19534 This is done atomically: even if multiple sessions
19535 execute
<function>nextval
</function> concurrently, each will safely
19536 receive a distinct sequence value.
19537 If the sequence object has been created with default parameters,
19538 successive
<function>nextval
</function> calls will return successive
19539 values beginning with
1. Other behaviors can be obtained by using
19540 appropriate parameters in the
<xref linkend=
"sql-createsequence"/>
19544 This function requires
<literal>USAGE
</literal>
19545 or
<literal>UPDATE
</literal> privilege on the sequence.
19550 <entry role=
"func_table_entry"><para role=
"func_signature">
19552 <primary>setval
</primary>
19554 <function>setval
</function> (
<type>regclass
</type>,
<type>bigint
</type> <optional>,
<type>boolean
</type> </optional> )
19555 <returnvalue>bigint
</returnvalue>
19558 Sets the sequence object's current value, and optionally
19559 its
<literal>is_called
</literal> flag. The two-parameter
19560 form sets the sequence's
<literal>last_value
</literal> field to the
19561 specified value and sets its
<literal>is_called
</literal> field to
19562 <literal>true
</literal>, meaning that the next
19563 <function>nextval
</function> will advance the sequence before
19564 returning a value. The value that will be reported
19565 by
<function>currval
</function> is also set to the specified value.
19566 In the three-parameter form,
<literal>is_called
</literal> can be set
19567 to either
<literal>true
</literal>
19568 or
<literal>false
</literal>.
<literal>true
</literal> has the same
19569 effect as the two-parameter form. If it is set
19570 to
<literal>false
</literal>, the next
<function>nextval
</function>
19571 will return exactly the specified value, and sequence advancement
19572 commences with the following
<function>nextval
</function>.
19573 Furthermore, the value reported by
<function>currval
</function> is not
19574 changed in this case. For example,
19576 SELECT setval('myseq',
42);
<lineannotation>Next
<function>nextval
</function> will return
43</lineannotation>
19577 SELECT setval('myseq',
42, true);
<lineannotation>Same as above
</lineannotation>
19578 SELECT setval('myseq',
42, false);
<lineannotation>Next
<function>nextval
</function> will return
42</lineannotation>
19580 The result returned by
<function>setval
</function> is just the value of its
19584 This function requires
<literal>UPDATE
</literal> privilege on the
19590 <entry role=
"func_table_entry"><para role=
"func_signature">
19592 <primary>currval
</primary>
19594 <function>currval
</function> (
<type>regclass
</type> )
19595 <returnvalue>bigint
</returnvalue>
19598 Returns the value most recently obtained
19599 by
<function>nextval
</function> for this sequence in the current
19600 session. (An error is reported if
<function>nextval
</function> has
19601 never been called for this sequence in this session.) Because this is
19602 returning a session-local value, it gives a predictable answer whether
19603 or not other sessions have executed
<function>nextval
</function> since
19604 the current session did.
19607 This function requires
<literal>USAGE
</literal>
19608 or
<literal>SELECT
</literal> privilege on the sequence.
19613 <entry role=
"func_table_entry"><para role=
"func_signature">
19615 <primary>lastval
</primary>
19617 <function>lastval
</function> ()
19618 <returnvalue>bigint
</returnvalue>
19621 Returns the value most recently returned by
19622 <function>nextval
</function> in the current session. This function is
19623 identical to
<function>currval
</function>, except that instead
19624 of taking the sequence name as an argument it refers to whichever
19625 sequence
<function>nextval
</function> was most recently applied to
19626 in the current session. It is an error to call
19627 <function>lastval
</function> if
<function>nextval
</function>
19628 has not yet been called in the current session.
19631 This function requires
<literal>USAGE
</literal>
19632 or
<literal>SELECT
</literal> privilege on the last used sequence.
19641 To avoid blocking concurrent transactions that obtain numbers from
19642 the same sequence, the value obtained by
<function>nextval
</function>
19643 is not reclaimed for re-use if the calling transaction later aborts.
19644 This means that transaction aborts or database crashes can result in
19645 gaps in the sequence of assigned values. That can happen without a
19646 transaction abort, too. For example an
<command>INSERT
</command> with
19647 an
<literal>ON CONFLICT
</literal> clause will compute the to-be-inserted
19648 tuple, including doing any required
<function>nextval
</function>
19649 calls, before detecting any conflict that would cause it to follow
19650 the
<literal>ON CONFLICT
</literal> rule instead.
19651 Thus,
<productname>PostgreSQL
</productname> sequence
19652 objects
<emphasis>cannot be used to obtain
<quote>gapless
</quote>
19653 sequences
</emphasis>.
19657 Likewise, sequence state changes made by
<function>setval
</function>
19658 are immediately visible to other transactions, and are not undone if
19659 the calling transaction rolls back.
19663 If the database cluster crashes before committing a transaction
19664 containing a
<function>nextval
</function>
19665 or
<function>setval
</function> call, the sequence state change might
19666 not have made its way to persistent storage, so that it is uncertain
19667 whether the sequence will have its original or updated state after the
19668 cluster restarts. This is harmless for usage of the sequence within
19669 the database, since other effects of uncommitted transactions will not
19670 be visible either. However, if you wish to use a sequence value for
19671 persistent outside-the-database purposes, make sure that the
19672 <function>nextval
</function> call has been committed before doing so.
19677 The sequence to be operated on by a sequence function is specified by
19678 a
<type>regclass
</type> argument, which is simply the OID of the sequence in the
19679 <structname>pg_class
</structname> system catalog. You do not have to look up the
19680 OID by hand, however, since the
<type>regclass
</type> data type's input
19681 converter will do the work for you. See
<xref linkend=
"datatype-oid"/>
19687 <sect1 id=
"functions-conditional">
19688 <title>Conditional Expressions
</title>
19691 <primary>CASE
</primary>
19695 <primary>conditional expression
</primary>
19699 This section describes the
<acronym>SQL
</acronym>-compliant conditional expressions
19700 available in
<productname>PostgreSQL
</productname>.
19705 If your needs go beyond the capabilities of these conditional
19706 expressions, you might want to consider writing a server-side function
19707 in a more expressive programming language.
19713 Although
<token>COALESCE
</token>,
<token>GREATEST
</token>, and
19714 <token>LEAST
</token> are syntactically similar to functions, they are
19715 not ordinary functions, and thus cannot be used with explicit
19716 <token>VARIADIC
</token> array arguments.
19720 <sect2 id=
"functions-case">
19721 <title><literal>CASE
</literal></title>
19724 The
<acronym>SQL
</acronym> <token>CASE
</token> expression is a
19725 generic conditional expression, similar to if/else statements in
19726 other programming languages:
19729 CASE WHEN
<replaceable>condition
</replaceable> THEN
<replaceable>result
</replaceable>
19730 <optional>WHEN ...
</optional>
19731 <optional>ELSE
<replaceable>result
</replaceable></optional>
19735 <token>CASE
</token> clauses can be used wherever
19736 an expression is valid. Each
<replaceable>condition
</replaceable> is an
19737 expression that returns a
<type>boolean
</type> result. If the condition's
19738 result is true, the value of the
<token>CASE
</token> expression is the
19739 <replaceable>result
</replaceable> that follows the condition, and the
19740 remainder of the
<token>CASE
</token> expression is not processed. If the
19741 condition's result is not true, any subsequent
<token>WHEN
</token> clauses
19742 are examined in the same manner. If no
<token>WHEN
</token>
19743 <replaceable>condition
</replaceable> yields true, the value of the
19744 <token>CASE
</token> expression is the
<replaceable>result
</replaceable> of the
19745 <token>ELSE
</token> clause. If the
<token>ELSE
</token> clause is
19746 omitted and no condition is true, the result is null.
19752 SELECT * FROM test;
19762 CASE WHEN a=
1 THEN 'one'
19763 WHEN a=
2 THEN 'two'
19777 The data types of all the
<replaceable>result
</replaceable>
19778 expressions must be convertible to a single output type.
19779 See
<xref linkend=
"typeconv-union-case"/> for more details.
19783 There is a
<quote>simple
</quote> form of
<token>CASE
</token> expression
19784 that is a variant of the general form above:
19787 CASE
<replaceable>expression
</replaceable>
19788 WHEN
<replaceable>value
</replaceable> THEN
<replaceable>result
</replaceable>
19789 <optional>WHEN ...
</optional>
19790 <optional>ELSE
<replaceable>result
</replaceable></optional>
19795 <replaceable>expression
</replaceable> is computed, then compared to
19796 each of the
<replaceable>value
</replaceable> expressions in the
19797 <token>WHEN
</token> clauses until one is found that is equal to it. If
19798 no match is found, the
<replaceable>result
</replaceable> of the
19799 <token>ELSE
</token> clause (or a null value) is returned. This is similar
19800 to the
<function>switch
</function> statement in C.
19804 The example above can be written using the simple
19805 <token>CASE
</token> syntax:
19808 CASE a WHEN
1 THEN 'one'
19823 A
<token>CASE
</token> expression does not evaluate any subexpressions
19824 that are not needed to determine the result. For example, this is a
19825 possible way of avoiding a division-by-zero failure:
19827 SELECT ... WHERE CASE WHEN x
<> 0 THEN y/x
> 1.5 ELSE false END;
19833 As described in
<xref linkend=
"syntax-express-eval"/>, there are various
19834 situations in which subexpressions of an expression are evaluated at
19835 different times, so that the principle that
<quote><token>CASE
</token>
19836 evaluates only necessary subexpressions
</quote> is not ironclad. For
19837 example a constant
<literal>1/
0</literal> subexpression will usually result in
19838 a division-by-zero failure at planning time, even if it's within
19839 a
<token>CASE
</token> arm that would never be entered at run time.
19844 <sect2 id=
"functions-coalesce-nvl-ifnull">
19845 <title><literal>COALESCE
</literal></title>
19848 <primary>COALESCE
</primary>
19852 <primary>NVL
</primary>
19856 <primary>IFNULL
</primary>
19860 <function>COALESCE
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
19864 The
<function>COALESCE
</function> function returns the first of its
19865 arguments that is not null. Null is returned only if all arguments
19866 are null. It is often used to substitute a default value for
19867 null values when data is retrieved for display, for example:
19869 SELECT COALESCE(description, short_description, '(none)') ...
19871 This returns
<varname>description
</varname> if it is not null, otherwise
19872 <varname>short_description
</varname> if it is not null, otherwise
<literal>(none)
</literal>.
19876 The arguments must all be convertible to a common data type, which
19877 will be the type of the result (see
19878 <xref linkend=
"typeconv-union-case"/> for details).
19882 Like a
<token>CASE
</token> expression,
<function>COALESCE
</function> only
19883 evaluates the arguments that are needed to determine the result;
19884 that is, arguments to the right of the first non-null argument are
19885 not evaluated. This SQL-standard function provides capabilities similar
19886 to
<function>NVL
</function> and
<function>IFNULL
</function>, which are used in some other
19891 <sect2 id=
"functions-nullif">
19892 <title><literal>NULLIF
</literal></title>
19895 <primary>NULLIF
</primary>
19899 <function>NULLIF
</function>(
<replaceable>value1
</replaceable>,
<replaceable>value2
</replaceable>)
19903 The
<function>NULLIF
</function> function returns a null value if
19904 <replaceable>value1
</replaceable> equals
<replaceable>value2
</replaceable>;
19905 otherwise it returns
<replaceable>value1
</replaceable>.
19906 This can be used to perform the inverse operation of the
19907 <function>COALESCE
</function> example given above:
19909 SELECT NULLIF(value, '(none)') ...
19911 In this example, if
<literal>value
</literal> is
<literal>(none)
</literal>,
19912 null is returned, otherwise the value of
<literal>value
</literal>
19917 The two arguments must be of comparable types.
19918 To be specific, they are compared exactly as if you had
19919 written
<literal><replaceable>value1
</replaceable>
19920 =
<replaceable>value2
</replaceable></literal>, so there must be a
19921 suitable
<literal>=
</literal> operator available.
19925 The result has the same type as the first argument
— but there is
19926 a subtlety. What is actually returned is the first argument of the
19927 implied
<literal>=
</literal> operator, and in some cases that will have
19928 been promoted to match the second argument's type. For
19929 example,
<literal>NULLIF(
1,
2.2)
</literal> yields
<type>numeric
</type>,
19930 because there is no
<type>integer
</type> <literal>=
</literal>
19931 <type>numeric
</type> operator,
19932 only
<type>numeric
</type> <literal>=
</literal> <type>numeric
</type>.
19937 <sect2 id=
"functions-greatest-least">
19938 <title><literal>GREATEST
</literal> and
<literal>LEAST
</literal></title>
19941 <primary>GREATEST
</primary>
19944 <primary>LEAST
</primary>
19948 <function>GREATEST
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
19951 <function>LEAST
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
19955 The
<function>GREATEST
</function> and
<function>LEAST
</function> functions select the
19956 largest or smallest value from a list of any number of expressions.
19957 The expressions must all be convertible to a common data type, which
19958 will be the type of the result
19959 (see
<xref linkend=
"typeconv-union-case"/> for details).
19963 NULL values in the argument list are ignored. The result will be NULL
19964 only if all the expressions evaluate to NULL. (This is a deviation from
19965 the SQL standard. According to the standard, the return value is NULL if
19966 any argument is NULL. Some other databases behave this way.)
19971 <sect1 id=
"functions-array">
19972 <title>Array Functions and Operators
</title>
19975 <xref linkend=
"array-operators-table"/> shows the specialized operators
19976 available for array types.
19977 In addition to those, the usual comparison operators shown in
<xref
19978 linkend=
"functions-comparison-op-table"/> are available for
19979 arrays. The comparison operators compare the array contents
19980 element-by-element, using the default B-tree comparison function for
19981 the element data type, and sort based on the first difference.
19982 In multidimensional arrays the elements are visited in row-major order
19983 (last subscript varies most rapidly).
19984 If the contents of two arrays are equal but the dimensionality is
19985 different, the first difference in the dimensionality information
19986 determines the sort order.
19989 <table id=
"array-operators-table">
19990 <title>Array Operators
</title>
19994 <entry role=
"func_table_entry"><para role=
"func_signature">
20008 <entry role=
"func_table_entry"><para role=
"func_signature">
20009 <type>anyarray
</type> <literal>@
></literal> <type>anyarray
</type>
20010 <returnvalue>boolean
</returnvalue>
20013 Does the first array contain the second, that is, does each element
20014 appearing in the second array equal some element of the first array?
20015 (Duplicates are not treated specially,
20016 thus
<literal>ARRAY[
1]
</literal> and
<literal>ARRAY[
1,
1]
</literal> are
20017 each considered to contain the other.)
20020 <literal>ARRAY[
1,
4,
3] @
> ARRAY[
3,
1,
3]
</literal>
20021 <returnvalue>t
</returnvalue>
20026 <entry role=
"func_table_entry"><para role=
"func_signature">
20027 <type>anyarray
</type> <literal><@
</literal> <type>anyarray
</type>
20028 <returnvalue>boolean
</returnvalue>
20031 Is the first array contained by the second?
20034 <literal>ARRAY[
2,
2,
7]
<@ ARRAY[
1,
7,
4,
2,
6]
</literal>
20035 <returnvalue>t
</returnvalue>
20040 <entry role=
"func_table_entry"><para role=
"func_signature">
20041 <type>anyarray
</type> <literal>&&</literal> <type>anyarray
</type>
20042 <returnvalue>boolean
</returnvalue>
20045 Do the arrays overlap, that is, have any elements in common?
20048 <literal>ARRAY[
1,
4,
3]
&& ARRAY[
2,
1]
</literal>
20049 <returnvalue>t
</returnvalue>
20054 <entry role=
"func_table_entry"><para role=
"func_signature">
20055 <type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20056 <returnvalue>anycompatiblearray
</returnvalue>
20059 Concatenates the two arrays. Concatenating a null or empty array is a
20060 no-op; otherwise the arrays must have the same number of dimensions
20061 (as illustrated by the first example) or differ in number of
20062 dimensions by one (as illustrated by the second).
20063 If the arrays are not of identical element types, they will be coerced
20064 to a common type (see
<xref linkend=
"typeconv-union-case"/>).
20067 <literal>ARRAY[
1,
2,
3] || ARRAY[
4,
5,
6,
7]
</literal>
20068 <returnvalue>{
1,
2,
3,
4,
5,
6,
7}
</returnvalue>
20071 <literal>ARRAY[
1,
2,
3] || ARRAY[[
4,
5,
6],[
7,
8,
9.9]]
</literal>
20072 <returnvalue>{{
1,
2,
3},{
4,
5,
6},{
7,
8,
9.9}}
</returnvalue>
20077 <entry role=
"func_table_entry"><para role=
"func_signature">
20078 <type>anycompatible
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20079 <returnvalue>anycompatiblearray
</returnvalue>
20082 Concatenates an element onto the front of an array (which must be
20083 empty or one-dimensional).
20086 <literal>3 || ARRAY[
4,
5,
6]
</literal>
20087 <returnvalue>{
3,
4,
5,
6}
</returnvalue>
20092 <entry role=
"func_table_entry"><para role=
"func_signature">
20093 <type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatible
</type>
20094 <returnvalue>anycompatiblearray
</returnvalue>
20097 Concatenates an element onto the end of an array (which must be
20098 empty or one-dimensional).
20101 <literal>ARRAY[
4,
5,
6] ||
7</literal>
20102 <returnvalue>{
4,
5,
6,
7}
</returnvalue>
20110 See
<xref linkend=
"arrays"/> for more details about array operator
20111 behavior. See
<xref linkend=
"indexes-types"/> for more details about
20112 which operators support indexed operations.
20116 <xref linkend=
"array-functions-table"/> shows the functions
20117 available for use with array types. See
<xref linkend=
"arrays"/>
20118 for more information and examples of the use of these functions.
20121 <table id=
"array-functions-table">
20122 <title>Array Functions
</title>
20126 <entry role=
"func_table_entry"><para role=
"func_signature">
20140 <entry role=
"func_table_entry"><para role=
"func_signature">
20142 <primary>array_append
</primary>
20144 <function>array_append
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
20145 <returnvalue>anycompatiblearray
</returnvalue>
20148 Appends an element to the end of an array (same as
20149 the
<type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatible
</type>
20153 <literal>array_append(ARRAY[
1,
2],
3)
</literal>
20154 <returnvalue>{
1,
2,
3}
</returnvalue>
20159 <entry role=
"func_table_entry"><para role=
"func_signature">
20161 <primary>array_cat
</primary>
20163 <function>array_cat
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatiblearray
</type> )
20164 <returnvalue>anycompatiblearray
</returnvalue>
20167 Concatenates two arrays (same as
20168 the
<type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20172 <literal>array_cat(ARRAY[
1,
2,
3], ARRAY[
4,
5])
</literal>
20173 <returnvalue>{
1,
2,
3,
4,
5}
</returnvalue>
20178 <entry role=
"func_table_entry"><para role=
"func_signature">
20180 <primary>array_dims
</primary>
20182 <function>array_dims
</function> (
<type>anyarray
</type> )
20183 <returnvalue>text
</returnvalue>
20186 Returns a text representation of the array's dimensions.
20189 <literal>array_dims(ARRAY[[
1,
2,
3], [
4,
5,
6]])
</literal>
20190 <returnvalue>[
1:
2][
1:
3]
</returnvalue>
20195 <entry role=
"func_table_entry"><para role=
"func_signature">
20197 <primary>array_fill
</primary>
20199 <function>array_fill
</function> (
<type>anyelement
</type>,
<type>integer[]
</type>
20200 <optional>,
<type>integer[]
</type> </optional> )
20201 <returnvalue>anyarray
</returnvalue>
20204 Returns an array filled with copies of the given value, having
20205 dimensions of the lengths specified by the second argument.
20206 The optional third argument supplies lower-bound values for each
20207 dimension (which default to all
<literal>1</literal>).
20210 <literal>array_fill(
11, ARRAY[
2,
3])
</literal>
20211 <returnvalue>{{
11,
11,
11},{
11,
11,
11}}
</returnvalue>
20214 <literal>array_fill(
7, ARRAY[
3], ARRAY[
2])
</literal>
20215 <returnvalue>[
2:
4]={
7,
7,
7}
</returnvalue>
20220 <entry role=
"func_table_entry"><para role=
"func_signature">
20222 <primary>array_length
</primary>
20224 <function>array_length
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
20225 <returnvalue>integer
</returnvalue>
20228 Returns the length of the requested array dimension.
20229 (Produces NULL instead of
0 for empty or missing array dimensions.)
20232 <literal>array_length(array[
1,
2,
3],
1)
</literal>
20233 <returnvalue>3</returnvalue>
20236 <literal>array_length(array[]::int[],
1)
</literal>
20237 <returnvalue>NULL
</returnvalue>
20240 <literal>array_length(array['text'],
2)
</literal>
20241 <returnvalue>NULL
</returnvalue>
20246 <entry role=
"func_table_entry"><para role=
"func_signature">
20248 <primary>array_lower
</primary>
20250 <function>array_lower
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
20251 <returnvalue>integer
</returnvalue>
20254 Returns the lower bound of the requested array dimension.
20257 <literal>array_lower('[
0:
2]={
1,
2,
3}'::integer[],
1)
</literal>
20258 <returnvalue>0</returnvalue>
20263 <entry role=
"func_table_entry"><para role=
"func_signature">
20265 <primary>array_ndims
</primary>
20267 <function>array_ndims
</function> (
<type>anyarray
</type> )
20268 <returnvalue>integer
</returnvalue>
20271 Returns the number of dimensions of the array.
20274 <literal>array_ndims(ARRAY[[
1,
2,
3], [
4,
5,
6]])
</literal>
20275 <returnvalue>2</returnvalue>
20280 <entry role=
"func_table_entry"><para role=
"func_signature">
20282 <primary>array_position
</primary>
20284 <function>array_position
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> <optional>,
<type>integer
</type> </optional> )
20285 <returnvalue>integer
</returnvalue>
20288 Returns the subscript of the first occurrence of the second argument
20289 in the array, or
<literal>NULL
</literal> if it's not present.
20290 If the third argument is given, the search begins at that subscript.
20291 The array must be one-dimensional.
20292 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
20293 semantics, so it is possible to search for
<literal>NULL
</literal>.
20296 <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')
</literal>
20297 <returnvalue>2</returnvalue>
20302 <entry role=
"func_table_entry"><para role=
"func_signature">
20304 <primary>array_positions
</primary>
20306 <function>array_positions
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
20307 <returnvalue>integer[]
</returnvalue>
20310 Returns an array of the subscripts of all occurrences of the second
20311 argument in the array given as first argument.
20312 The array must be one-dimensional.
20313 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
20314 semantics, so it is possible to search for
<literal>NULL
</literal>.
20315 <literal>NULL
</literal> is returned only if the array
20316 is
<literal>NULL
</literal>; if the value is not found in the array, an
20317 empty array is returned.
20320 <literal>array_positions(ARRAY['A','A','B','A'], 'A')
</literal>
20321 <returnvalue>{
1,
2,
4}
</returnvalue>
20326 <entry role=
"func_table_entry"><para role=
"func_signature">
20328 <primary>array_prepend
</primary>
20330 <function>array_prepend
</function> (
<type>anycompatible
</type>,
<type>anycompatiblearray
</type> )
20331 <returnvalue>anycompatiblearray
</returnvalue>
20334 Prepends an element to the beginning of an array (same as
20335 the
<type>anycompatible
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
20339 <literal>array_prepend(
1, ARRAY[
2,
3])
</literal>
20340 <returnvalue>{
1,
2,
3}
</returnvalue>
20345 <entry role=
"func_table_entry"><para role=
"func_signature">
20347 <primary>array_remove
</primary>
20349 <function>array_remove
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
20350 <returnvalue>anycompatiblearray
</returnvalue>
20353 Removes all elements equal to the given value from the array.
20354 The array must be one-dimensional.
20355 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
20356 semantics, so it is possible to remove
<literal>NULL
</literal>s.
20359 <literal>array_remove(ARRAY[
1,
2,
3,
2],
2)
</literal>
20360 <returnvalue>{
1,
3}
</returnvalue>
20365 <entry role=
"func_table_entry"><para role=
"func_signature">
20367 <primary>array_replace
</primary>
20369 <function>array_replace
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type>,
<type>anycompatible
</type> )
20370 <returnvalue>anycompatiblearray
</returnvalue>
20373 Replaces each array element equal to the second argument with the
20377 <literal>array_replace(ARRAY[
1,
2,
5,
4],
5,
3)
</literal>
20378 <returnvalue>{
1,
2,
3,
4}
</returnvalue>
20383 <entry role=
"func_table_entry"><para role=
"func_signature">
20385 <primary>array_reverse
</primary>
20387 <function>array_reverse
</function> (
<type>anyarray
</type> )
20388 <returnvalue>anyarray
</returnvalue>
20391 Reverses the first dimension of the array.
20394 <literal>array_reverse(ARRAY[[
1,
2],[
3,
4],[
5,
6]])
</literal>
20395 <returnvalue>{{
5,
6},{
3,
4},{
1,
2}}
</returnvalue>
20400 <entry role=
"func_table_entry"><para role=
"func_signature">
20402 <primary>array_sample
</primary>
20404 <function>array_sample
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>n
</parameter> <type>integer
</type> )
20405 <returnvalue>anyarray
</returnvalue>
20408 Returns an array of
<parameter>n
</parameter> items randomly selected
20409 from
<parameter>array
</parameter>.
<parameter>n
</parameter> may not
20410 exceed the length of
<parameter>array
</parameter>'s first dimension.
20411 If
<parameter>array
</parameter> is multi-dimensional,
20412 an
<quote>item
</quote> is a slice having a given first subscript.
20415 <literal>array_sample(ARRAY[
1,
2,
3,
4,
5,
6],
3)
</literal>
20416 <returnvalue>{
2,
6,
1}
</returnvalue>
20419 <literal>array_sample(ARRAY[[
1,
2],[
3,
4],[
5,
6]],
2)
</literal>
20420 <returnvalue>{{
5,
6},{
1,
2}}
</returnvalue>
20425 <entry role=
"func_table_entry"><para role=
"func_signature">
20427 <primary>array_shuffle
</primary>
20429 <function>array_shuffle
</function> (
<type>anyarray
</type> )
20430 <returnvalue>anyarray
</returnvalue>
20433 Randomly shuffles the first dimension of the array.
20436 <literal>array_shuffle(ARRAY[[
1,
2],[
3,
4],[
5,
6]])
</literal>
20437 <returnvalue>{{
5,
6},{
1,
2},{
3,
4}}
</returnvalue>
20442 <entry role=
"func_table_entry"><para role=
"func_signature">
20443 <indexterm id=
"function-array-to-string">
20444 <primary>array_to_string
</primary>
20446 <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> )
20447 <returnvalue>text
</returnvalue>
20450 Converts each array element to its text representation, and
20451 concatenates those separated by
20452 the
<parameter>delimiter
</parameter> string.
20453 If
<parameter>null_string
</parameter> is given and is
20454 not
<literal>NULL
</literal>, then
<literal>NULL
</literal> array
20455 entries are represented by that string; otherwise, they are omitted.
20456 See also
<link linkend=
"function-string-to-array"><function>string_to_array
</function></link>.
20459 <literal>array_to_string(ARRAY[
1,
2,
3, NULL,
5], ',', '*')
</literal>
20460 <returnvalue>1,
2,
3,*,
5</returnvalue>
20465 <entry role=
"func_table_entry"><para role=
"func_signature">
20467 <primary>array_upper
</primary>
20469 <function>array_upper
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
20470 <returnvalue>integer
</returnvalue>
20473 Returns the upper bound of the requested array dimension.
20476 <literal>array_upper(ARRAY[
1,
8,
3,
7],
1)
</literal>
20477 <returnvalue>4</returnvalue>
20482 <entry role=
"func_table_entry"><para role=
"func_signature">
20484 <primary>cardinality
</primary>
20486 <function>cardinality
</function> (
<type>anyarray
</type> )
20487 <returnvalue>integer
</returnvalue>
20490 Returns the total number of elements in the array, or
0 if the array
20494 <literal>cardinality(ARRAY[[
1,
2],[
3,
4]])
</literal>
20495 <returnvalue>4</returnvalue>
20500 <entry role=
"func_table_entry"><para role=
"func_signature">
20502 <primary>trim_array
</primary>
20504 <function>trim_array
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>n
</parameter> <type>integer
</type> )
20505 <returnvalue>anyarray
</returnvalue>
20508 Trims an array by removing the last
<parameter>n
</parameter> elements.
20509 If the array is multidimensional, only the first dimension is trimmed.
20512 <literal>trim_array(ARRAY[
1,
2,
3,
4,
5,
6],
2)
</literal>
20513 <returnvalue>{
1,
2,
3,
4}
</returnvalue>
20518 <entry role=
"func_table_entry"><para role=
"func_signature">
20520 <primary>unnest
</primary>
20522 <function>unnest
</function> (
<type>anyarray
</type> )
20523 <returnvalue>setof anyelement
</returnvalue>
20526 Expands an array into a set of rows.
20527 The array's elements are read out in storage order.
20530 <literal>unnest(ARRAY[
1,
2])
</literal>
20531 <returnvalue></returnvalue>
20538 <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])
</literal>
20539 <returnvalue></returnvalue>
20550 <entry role=
"func_table_entry"><para role=
"func_signature">
20551 <function>unnest
</function> (
<type>anyarray
</type>,
<type>anyarray
</type> <optional>, ...
</optional> )
20552 <returnvalue>setof anyelement, anyelement [, ... ]
</returnvalue>
20555 Expands multiple arrays (possibly of different data types) into a set of
20556 rows. If the arrays are not all the same length then the shorter ones
20557 are padded with
<literal>NULL
</literal>s. This form is only allowed
20558 in a query's FROM clause; see
<xref linkend=
"queries-tablefunctions"/>.
20561 <literal>select * from unnest(ARRAY[
1,
2], ARRAY['foo','bar','baz']) as x(a,b)
</literal>
20562 <returnvalue></returnvalue>
20577 See also
<xref linkend=
"functions-aggregate"/> about the aggregate
20578 function
<function>array_agg
</function> for use with arrays.
20582 <sect1 id=
"functions-range">
20583 <title>Range/Multirange Functions and Operators
</title>
20586 See
<xref linkend=
"rangetypes"/> for an overview of range types.
20590 <xref linkend=
"range-operators-table"/> shows the specialized operators
20591 available for range types.
20592 <xref linkend=
"multirange-operators-table"/> shows the specialized operators
20593 available for multirange types.
20594 In addition to those, the usual comparison operators shown in
20595 <xref linkend=
"functions-comparison-op-table"/> are available for range
20596 and multirange types. The comparison operators order first by the range lower
20597 bounds, and only if those are equal do they compare the upper bounds. The
20598 multirange operators compare each range until one is unequal. This
20599 does not usually result in a useful overall ordering, but the operators are
20600 provided to allow unique indexes to be constructed on ranges.
20603 <table id=
"range-operators-table">
20604 <title>Range Operators
</title>
20608 <entry role=
"func_table_entry"><para role=
"func_signature">
20622 <entry role=
"func_table_entry"><para role=
"func_signature">
20623 <type>anyrange
</type> <literal>@
></literal> <type>anyrange
</type>
20624 <returnvalue>boolean
</returnvalue>
20627 Does the first range contain the second?
20630 <literal>int4range(
2,
4) @
> int4range(
2,
3)
</literal>
20631 <returnvalue>t
</returnvalue>
20636 <entry role=
"func_table_entry"><para role=
"func_signature">
20637 <type>anyrange
</type> <literal>@
></literal> <type>anyelement
</type>
20638 <returnvalue>boolean
</returnvalue>
20641 Does the range contain the element?
20644 <literal>'[
2011-
01-
01,
2011-
03-
01)'::tsrange @
> '
2011-
01-
10'::timestamp
</literal>
20645 <returnvalue>t
</returnvalue>
20650 <entry role=
"func_table_entry"><para role=
"func_signature">
20651 <type>anyrange
</type> <literal><@
</literal> <type>anyrange
</type>
20652 <returnvalue>boolean
</returnvalue>
20655 Is the first range contained by the second?
20658 <literal>int4range(
2,
4)
<@ int4range(
1,
7)
</literal>
20659 <returnvalue>t
</returnvalue>
20664 <entry role=
"func_table_entry"><para role=
"func_signature">
20665 <type>anyelement
</type> <literal><@
</literal> <type>anyrange
</type>
20666 <returnvalue>boolean
</returnvalue>
20669 Is the element contained in the range?
20672 <literal>42 <@ int4range(
1,
7)
</literal>
20673 <returnvalue>f
</returnvalue>
20678 <entry role=
"func_table_entry"><para role=
"func_signature">
20679 <type>anyrange
</type> <literal>&&</literal> <type>anyrange
</type>
20680 <returnvalue>boolean
</returnvalue>
20683 Do the ranges overlap, that is, have any elements in common?
20686 <literal>int8range(
3,
7)
&& int8range(
4,
12)
</literal>
20687 <returnvalue>t
</returnvalue>
20692 <entry role=
"func_table_entry"><para role=
"func_signature">
20693 <type>anyrange
</type> <literal><<</literal> <type>anyrange
</type>
20694 <returnvalue>boolean
</returnvalue>
20697 Is the first range strictly left of the second?
20700 <literal>int8range(
1,
10)
<< int8range(
100,
110)
</literal>
20701 <returnvalue>t
</returnvalue>
20706 <entry role=
"func_table_entry"><para role=
"func_signature">
20707 <type>anyrange
</type> <literal>>></literal> <type>anyrange
</type>
20708 <returnvalue>boolean
</returnvalue>
20711 Is the first range strictly right of the second?
20714 <literal>int8range(
50,
60)
>> int8range(
20,
30)
</literal>
20715 <returnvalue>t
</returnvalue>
20720 <entry role=
"func_table_entry"><para role=
"func_signature">
20721 <type>anyrange
</type> <literal>&<</literal> <type>anyrange
</type>
20722 <returnvalue>boolean
</returnvalue>
20725 Does the first range not extend to the right of the second?
20728 <literal>int8range(
1,
20)
&< int8range(
18,
20)
</literal>
20729 <returnvalue>t
</returnvalue>
20734 <entry role=
"func_table_entry"><para role=
"func_signature">
20735 <type>anyrange
</type> <literal>&></literal> <type>anyrange
</type>
20736 <returnvalue>boolean
</returnvalue>
20739 Does the first range not extend to the left of the second?
20742 <literal>int8range(
7,
20)
&> int8range(
5,
10)
</literal>
20743 <returnvalue>t
</returnvalue>
20748 <entry role=
"func_table_entry"><para role=
"func_signature">
20749 <type>anyrange
</type> <literal>-|-
</literal> <type>anyrange
</type>
20750 <returnvalue>boolean
</returnvalue>
20753 Are the ranges adjacent?
20756 <literal>numrange(
1.1,
2.2) -|- numrange(
2.2,
3.3)
</literal>
20757 <returnvalue>t
</returnvalue>
20762 <entry role=
"func_table_entry"><para role=
"func_signature">
20763 <type>anyrange
</type> <literal>+
</literal> <type>anyrange
</type>
20764 <returnvalue>anyrange
</returnvalue>
20767 Computes the union of the ranges. The ranges must overlap or be
20768 adjacent, so that the union is a single range (but
20769 see
<function>range_merge()
</function>).
20772 <literal>numrange(
5,
15) + numrange(
10,
20)
</literal>
20773 <returnvalue>[
5,
20)
</returnvalue>
20778 <entry role=
"func_table_entry"><para role=
"func_signature">
20779 <type>anyrange
</type> <literal>*
</literal> <type>anyrange
</type>
20780 <returnvalue>anyrange
</returnvalue>
20783 Computes the intersection of the ranges.
20786 <literal>int8range(
5,
15) * int8range(
10,
20)
</literal>
20787 <returnvalue>[
10,
15)
</returnvalue>
20792 <entry role=
"func_table_entry"><para role=
"func_signature">
20793 <type>anyrange
</type> <literal>-
</literal> <type>anyrange
</type>
20794 <returnvalue>anyrange
</returnvalue>
20797 Computes the difference of the ranges. The second range must not be
20798 contained in the first in such a way that the difference would not be
20802 <literal>int8range(
5,
15) - int8range(
10,
20)
</literal>
20803 <returnvalue>[
5,
10)
</returnvalue>
20810 <table id=
"multirange-operators-table">
20811 <title>Multirange Operators
</title>
20815 <entry role=
"func_table_entry"><para role=
"func_signature">
20829 <entry role=
"func_table_entry"><para role=
"func_signature">
20830 <type>anymultirange
</type> <literal>@
></literal> <type>anymultirange
</type>
20831 <returnvalue>boolean
</returnvalue>
20834 Does the first multirange contain the second?
20837 <literal>'{[
2,
4)}'::int4multirange @
> '{[
2,
3)}'::int4multirange
</literal>
20838 <returnvalue>t
</returnvalue>
20843 <entry role=
"func_table_entry"><para role=
"func_signature">
20844 <type>anymultirange
</type> <literal>@
></literal> <type>anyrange
</type>
20845 <returnvalue>boolean
</returnvalue>
20848 Does the multirange contain the range?
20851 <literal>'{[
2,
4)}'::int4multirange @
> int4range(
2,
3)
</literal>
20852 <returnvalue>t
</returnvalue>
20857 <entry role=
"func_table_entry"><para role=
"func_signature">
20858 <type>anymultirange
</type> <literal>@
></literal> <type>anyelement
</type>
20859 <returnvalue>boolean
</returnvalue>
20862 Does the multirange contain the element?
20865 <literal>'{[
2011-
01-
01,
2011-
03-
01)}'::tsmultirange @
> '
2011-
01-
10'::timestamp
</literal>
20866 <returnvalue>t
</returnvalue>
20871 <entry role=
"func_table_entry"><para role=
"func_signature">
20872 <type>anyrange
</type> <literal>@
></literal> <type>anymultirange
</type>
20873 <returnvalue>boolean
</returnvalue>
20876 Does the range contain the multirange?
20879 <literal>'[
2,
4)'::int4range @
> '{[
2,
3)}'::int4multirange
</literal>
20880 <returnvalue>t
</returnvalue>
20885 <entry role=
"func_table_entry"><para role=
"func_signature">
20886 <type>anymultirange
</type> <literal><@
</literal> <type>anymultirange
</type>
20887 <returnvalue>boolean
</returnvalue>
20890 Is the first multirange contained by the second?
20893 <literal>'{[
2,
4)}'::int4multirange
<@ '{[
1,
7)}'::int4multirange
</literal>
20894 <returnvalue>t
</returnvalue>
20899 <entry role=
"func_table_entry"><para role=
"func_signature">
20900 <type>anymultirange
</type> <literal><@
</literal> <type>anyrange
</type>
20901 <returnvalue>boolean
</returnvalue>
20904 Is the multirange contained by the range?
20907 <literal>'{[
2,
4)}'::int4multirange
<@ int4range(
1,
7)
</literal>
20908 <returnvalue>t
</returnvalue>
20913 <entry role=
"func_table_entry"><para role=
"func_signature">
20914 <type>anyrange
</type> <literal><@
</literal> <type>anymultirange
</type>
20915 <returnvalue>boolean
</returnvalue>
20918 Is the range contained by the multirange?
20921 <literal>int4range(
2,
4)
<@ '{[
1,
7)}'::int4multirange
</literal>
20922 <returnvalue>t
</returnvalue>
20927 <entry role=
"func_table_entry"><para role=
"func_signature">
20928 <type>anyelement
</type> <literal><@
</literal> <type>anymultirange
</type>
20929 <returnvalue>boolean
</returnvalue>
20932 Is the element contained by the multirange?
20935 <literal>4 <@ '{[
1,
7)}'::int4multirange
</literal>
20936 <returnvalue>t
</returnvalue>
20941 <entry role=
"func_table_entry"><para role=
"func_signature">
20942 <type>anymultirange
</type> <literal>&&</literal> <type>anymultirange
</type>
20943 <returnvalue>boolean
</returnvalue>
20946 Do the multiranges overlap, that is, have any elements in common?
20949 <literal>'{[
3,
7)}'::int8multirange
&& '{[
4,
12)}'::int8multirange
</literal>
20950 <returnvalue>t
</returnvalue>
20955 <entry role=
"func_table_entry"><para role=
"func_signature">
20956 <type>anymultirange
</type> <literal>&&</literal> <type>anyrange
</type>
20957 <returnvalue>boolean
</returnvalue>
20960 Does the multirange overlap the range?
20963 <literal>'{[
3,
7)}'::int8multirange
&& int8range(
4,
12)
</literal>
20964 <returnvalue>t
</returnvalue>
20969 <entry role=
"func_table_entry"><para role=
"func_signature">
20970 <type>anyrange
</type> <literal>&&</literal> <type>anymultirange
</type>
20971 <returnvalue>boolean
</returnvalue>
20974 Does the range overlap the multirange?
20977 <literal>int8range(
3,
7)
&& '{[
4,
12)}'::int8multirange
</literal>
20978 <returnvalue>t
</returnvalue>
20983 <entry role=
"func_table_entry"><para role=
"func_signature">
20984 <type>anymultirange
</type> <literal><<</literal> <type>anymultirange
</type>
20985 <returnvalue>boolean
</returnvalue>
20988 Is the first multirange strictly left of the second?
20991 <literal>'{[
1,
10)}'::int8multirange
<< '{[
100,
110)}'::int8multirange
</literal>
20992 <returnvalue>t
</returnvalue>
20997 <entry role=
"func_table_entry"><para role=
"func_signature">
20998 <type>anymultirange
</type> <literal><<</literal> <type>anyrange
</type>
20999 <returnvalue>boolean
</returnvalue>
21002 Is the multirange strictly left of the range?
21005 <literal>'{[
1,
10)}'::int8multirange
<< int8range(
100,
110)
</literal>
21006 <returnvalue>t
</returnvalue>
21011 <entry role=
"func_table_entry"><para role=
"func_signature">
21012 <type>anyrange
</type> <literal><<</literal> <type>anymultirange
</type>
21013 <returnvalue>boolean
</returnvalue>
21016 Is the range strictly left of the multirange?
21019 <literal>int8range(
1,
10)
<< '{[
100,
110)}'::int8multirange
</literal>
21020 <returnvalue>t
</returnvalue>
21025 <entry role=
"func_table_entry"><para role=
"func_signature">
21026 <type>anymultirange
</type> <literal>>></literal> <type>anymultirange
</type>
21027 <returnvalue>boolean
</returnvalue>
21030 Is the first multirange strictly right of the second?
21033 <literal>'{[
50,
60)}'::int8multirange
>> '{[
20,
30)}'::int8multirange
</literal>
21034 <returnvalue>t
</returnvalue>
21039 <entry role=
"func_table_entry"><para role=
"func_signature">
21040 <type>anymultirange
</type> <literal>>></literal> <type>anyrange
</type>
21041 <returnvalue>boolean
</returnvalue>
21044 Is the multirange strictly right of the range?
21047 <literal>'{[
50,
60)}'::int8multirange
>> int8range(
20,
30)
</literal>
21048 <returnvalue>t
</returnvalue>
21053 <entry role=
"func_table_entry"><para role=
"func_signature">
21054 <type>anyrange
</type> <literal>>></literal> <type>anymultirange
</type>
21055 <returnvalue>boolean
</returnvalue>
21058 Is the range strictly right of the multirange?
21061 <literal>int8range(
50,
60)
>> '{[
20,
30)}'::int8multirange
</literal>
21062 <returnvalue>t
</returnvalue>
21067 <entry role=
"func_table_entry"><para role=
"func_signature">
21068 <type>anymultirange
</type> <literal>&<</literal> <type>anymultirange
</type>
21069 <returnvalue>boolean
</returnvalue>
21072 Does the first multirange not extend to the right of the second?
21075 <literal>'{[
1,
20)}'::int8multirange
&< '{[
18,
20)}'::int8multirange
</literal>
21076 <returnvalue>t
</returnvalue>
21081 <entry role=
"func_table_entry"><para role=
"func_signature">
21082 <type>anymultirange
</type> <literal>&<</literal> <type>anyrange
</type>
21083 <returnvalue>boolean
</returnvalue>
21086 Does the multirange not extend to the right of the range?
21089 <literal>'{[
1,
20)}'::int8multirange
&< int8range(
18,
20)
</literal>
21090 <returnvalue>t
</returnvalue>
21095 <entry role=
"func_table_entry"><para role=
"func_signature">
21096 <type>anyrange
</type> <literal>&<</literal> <type>anymultirange
</type>
21097 <returnvalue>boolean
</returnvalue>
21100 Does the range not extend to the right of the multirange?
21103 <literal>int8range(
1,
20)
&< '{[
18,
20)}'::int8multirange
</literal>
21104 <returnvalue>t
</returnvalue>
21109 <entry role=
"func_table_entry"><para role=
"func_signature">
21110 <type>anymultirange
</type> <literal>&></literal> <type>anymultirange
</type>
21111 <returnvalue>boolean
</returnvalue>
21114 Does the first multirange not extend to the left of the second?
21117 <literal>'{[
7,
20)}'::int8multirange
&> '{[
5,
10)}'::int8multirange
</literal>
21118 <returnvalue>t
</returnvalue>
21123 <entry role=
"func_table_entry"><para role=
"func_signature">
21124 <type>anymultirange
</type> <literal>&></literal> <type>anyrange
</type>
21125 <returnvalue>boolean
</returnvalue>
21128 Does the multirange not extend to the left of the range?
21131 <literal>'{[
7,
20)}'::int8multirange
&> int8range(
5,
10)
</literal>
21132 <returnvalue>t
</returnvalue>
21137 <entry role=
"func_table_entry"><para role=
"func_signature">
21138 <type>anyrange
</type> <literal>&></literal> <type>anymultirange
</type>
21139 <returnvalue>boolean
</returnvalue>
21142 Does the range not extend to the left of the multirange?
21145 <literal>int8range(
7,
20)
&> '{[
5,
10)}'::int8multirange
</literal>
21146 <returnvalue>t
</returnvalue>
21151 <entry role=
"func_table_entry"><para role=
"func_signature">
21152 <type>anymultirange
</type> <literal>-|-
</literal> <type>anymultirange
</type>
21153 <returnvalue>boolean
</returnvalue>
21156 Are the multiranges adjacent?
21159 <literal>'{[
1.1,
2.2)}'::nummultirange -|- '{[
2.2,
3.3)}'::nummultirange
</literal>
21160 <returnvalue>t
</returnvalue>
21165 <entry role=
"func_table_entry"><para role=
"func_signature">
21166 <type>anymultirange
</type> <literal>-|-
</literal> <type>anyrange
</type>
21167 <returnvalue>boolean
</returnvalue>
21170 Is the multirange adjacent to the range?
21173 <literal>'{[
1.1,
2.2)}'::nummultirange -|- numrange(
2.2,
3.3)
</literal>
21174 <returnvalue>t
</returnvalue>
21179 <entry role=
"func_table_entry"><para role=
"func_signature">
21180 <type>anyrange
</type> <literal>-|-
</literal> <type>anymultirange
</type>
21181 <returnvalue>boolean
</returnvalue>
21184 Is the range adjacent to the multirange?
21187 <literal>numrange(
1.1,
2.2) -|- '{[
2.2,
3.3)}'::nummultirange
</literal>
21188 <returnvalue>t
</returnvalue>
21193 <entry role=
"func_table_entry"><para role=
"func_signature">
21194 <type>anymultirange
</type> <literal>+
</literal> <type>anymultirange
</type>
21195 <returnvalue>anymultirange
</returnvalue>
21198 Computes the union of the multiranges. The multiranges need not overlap
21202 <literal>'{[
5,
10)}'::nummultirange + '{[
15,
20)}'::nummultirange
</literal>
21203 <returnvalue>{[
5,
10), [
15,
20)}
</returnvalue>
21208 <entry role=
"func_table_entry"><para role=
"func_signature">
21209 <type>anymultirange
</type> <literal>*
</literal> <type>anymultirange
</type>
21210 <returnvalue>anymultirange
</returnvalue>
21213 Computes the intersection of the multiranges.
21216 <literal>'{[
5,
15)}'::int8multirange * '{[
10,
20)}'::int8multirange
</literal>
21217 <returnvalue>{[
10,
15)}
</returnvalue>
21222 <entry role=
"func_table_entry"><para role=
"func_signature">
21223 <type>anymultirange
</type> <literal>-
</literal> <type>anymultirange
</type>
21224 <returnvalue>anymultirange
</returnvalue>
21227 Computes the difference of the multiranges.
21230 <literal>'{[
5,
20)}'::int8multirange - '{[
10,
15)}'::int8multirange
</literal>
21231 <returnvalue>{[
5,
10), [
15,
20)}
</returnvalue>
21239 The left-of/right-of/adjacent operators always return false when an empty
21240 range or multirange is involved; that is, an empty range is not considered to
21241 be either before or after any other range.
21245 Elsewhere empty ranges and multiranges are treated as the additive identity:
21246 anything unioned with an empty value is itself. Anything minus an empty
21247 value is itself. An empty multirange has exactly the same points as an empty
21248 range. Every range contains the empty range. Every multirange contains as many
21249 empty ranges as you like.
21253 The range union and difference operators will fail if the resulting range would
21254 need to contain two disjoint sub-ranges, as such a range cannot be
21255 represented. There are separate operators for union and difference that take
21256 multirange parameters and return a multirange, and they do not fail even if
21257 their arguments are disjoint. So if you need a union or difference operation
21258 for ranges that may be disjoint, you can avoid errors by first casting your
21259 ranges to multiranges.
21263 <xref linkend=
"range-functions-table"/> shows the functions
21264 available for use with range types.
21265 <xref linkend=
"multirange-functions-table"/> shows the functions
21266 available for use with multirange types.
21269 <table id=
"range-functions-table">
21270 <title>Range Functions
</title>
21274 <entry role=
"func_table_entry"><para role=
"func_signature">
21288 <entry role=
"func_table_entry"><para role=
"func_signature">
21290 <primary>lower
</primary>
21292 <function>lower
</function> (
<type>anyrange
</type> )
21293 <returnvalue>anyelement
</returnvalue>
21296 Extracts the lower bound of the range (
<literal>NULL
</literal> if the
21297 range is empty or has no lower bound).
21300 <literal>lower(numrange(
1.1,
2.2))
</literal>
21301 <returnvalue>1.1</returnvalue>
21306 <entry role=
"func_table_entry"><para role=
"func_signature">
21308 <primary>upper
</primary>
21310 <function>upper
</function> (
<type>anyrange
</type> )
21311 <returnvalue>anyelement
</returnvalue>
21314 Extracts the upper bound of the range (
<literal>NULL
</literal> if the
21315 range is empty or has no upper bound).
21318 <literal>upper(numrange(
1.1,
2.2))
</literal>
21319 <returnvalue>2.2</returnvalue>
21324 <entry role=
"func_table_entry"><para role=
"func_signature">
21326 <primary>isempty
</primary>
21328 <function>isempty
</function> (
<type>anyrange
</type> )
21329 <returnvalue>boolean
</returnvalue>
21332 Is the range empty?
21335 <literal>isempty(numrange(
1.1,
2.2))
</literal>
21336 <returnvalue>f
</returnvalue>
21341 <entry role=
"func_table_entry"><para role=
"func_signature">
21343 <primary>lower_inc
</primary>
21345 <function>lower_inc
</function> (
<type>anyrange
</type> )
21346 <returnvalue>boolean
</returnvalue>
21349 Is the range's lower bound inclusive?
21352 <literal>lower_inc(numrange(
1.1,
2.2))
</literal>
21353 <returnvalue>t
</returnvalue>
21358 <entry role=
"func_table_entry"><para role=
"func_signature">
21360 <primary>upper_inc
</primary>
21362 <function>upper_inc
</function> (
<type>anyrange
</type> )
21363 <returnvalue>boolean
</returnvalue>
21366 Is the range's upper bound inclusive?
21369 <literal>upper_inc(numrange(
1.1,
2.2))
</literal>
21370 <returnvalue>f
</returnvalue>
21375 <entry role=
"func_table_entry"><para role=
"func_signature">
21377 <primary>lower_inf
</primary>
21379 <function>lower_inf
</function> (
<type>anyrange
</type> )
21380 <returnvalue>boolean
</returnvalue>
21383 Does the range have no lower bound? (A lower bound of
21384 <literal>-Infinity
</literal> returns false.)
21387 <literal>lower_inf('(,)'::daterange)
</literal>
21388 <returnvalue>t
</returnvalue>
21393 <entry role=
"func_table_entry"><para role=
"func_signature">
21395 <primary>upper_inf
</primary>
21397 <function>upper_inf
</function> (
<type>anyrange
</type> )
21398 <returnvalue>boolean
</returnvalue>
21401 Does the range have no upper bound? (An upper bound of
21402 <literal>Infinity
</literal> returns false.)
21405 <literal>upper_inf('(,)'::daterange)
</literal>
21406 <returnvalue>t
</returnvalue>
21411 <entry role=
"func_table_entry"><para role=
"func_signature">
21413 <primary>range_merge
</primary>
21415 <function>range_merge
</function> (
<type>anyrange
</type>,
<type>anyrange
</type> )
21416 <returnvalue>anyrange
</returnvalue>
21419 Computes the smallest range that includes both of the given ranges.
21422 <literal>range_merge('[
1,
2)'::int4range, '[
3,
4)'::int4range)
</literal>
21423 <returnvalue>[
1,
4)
</returnvalue>
21430 <table id=
"multirange-functions-table">
21431 <title>Multirange Functions
</title>
21435 <entry role=
"func_table_entry"><para role=
"func_signature">
21448 <entry role=
"func_table_entry"><para role=
"func_signature">
21450 <primary>lower
</primary>
21452 <function>lower
</function> (
<type>anymultirange
</type> )
21453 <returnvalue>anyelement
</returnvalue>
21456 Extracts the lower bound of the multirange (
<literal>NULL
</literal> if the
21457 multirange is empty or has no lower bound).
21460 <literal>lower('{[
1.1,
2.2)}'::nummultirange)
</literal>
21461 <returnvalue>1.1</returnvalue>
21466 <entry role=
"func_table_entry"><para role=
"func_signature">
21468 <primary>upper
</primary>
21470 <function>upper
</function> (
<type>anymultirange
</type> )
21471 <returnvalue>anyelement
</returnvalue>
21474 Extracts the upper bound of the multirange (
<literal>NULL
</literal> if the
21475 multirange is empty or has no upper bound).
21478 <literal>upper('{[
1.1,
2.2)}'::nummultirange)
</literal>
21479 <returnvalue>2.2</returnvalue>
21484 <entry role=
"func_table_entry"><para role=
"func_signature">
21486 <primary>isempty
</primary>
21488 <function>isempty
</function> (
<type>anymultirange
</type> )
21489 <returnvalue>boolean
</returnvalue>
21492 Is the multirange empty?
21495 <literal>isempty('{[
1.1,
2.2)}'::nummultirange)
</literal>
21496 <returnvalue>f
</returnvalue>
21501 <entry role=
"func_table_entry"><para role=
"func_signature">
21503 <primary>lower_inc
</primary>
21505 <function>lower_inc
</function> (
<type>anymultirange
</type> )
21506 <returnvalue>boolean
</returnvalue>
21509 Is the multirange's lower bound inclusive?
21512 <literal>lower_inc('{[
1.1,
2.2)}'::nummultirange)
</literal>
21513 <returnvalue>t
</returnvalue>
21518 <entry role=
"func_table_entry"><para role=
"func_signature">
21520 <primary>upper_inc
</primary>
21522 <function>upper_inc
</function> (
<type>anymultirange
</type> )
21523 <returnvalue>boolean
</returnvalue>
21526 Is the multirange's upper bound inclusive?
21529 <literal>upper_inc('{[
1.1,
2.2)}'::nummultirange)
</literal>
21530 <returnvalue>f
</returnvalue>
21535 <entry role=
"func_table_entry"><para role=
"func_signature">
21537 <primary>lower_inf
</primary>
21539 <function>lower_inf
</function> (
<type>anymultirange
</type> )
21540 <returnvalue>boolean
</returnvalue>
21543 Does the multirange have no lower bound? (A lower bound of
21544 <literal>-Infinity
</literal> returns false.)
21547 <literal>lower_inf('{(,)}'::datemultirange)
</literal>
21548 <returnvalue>t
</returnvalue>
21553 <entry role=
"func_table_entry"><para role=
"func_signature">
21555 <primary>upper_inf
</primary>
21557 <function>upper_inf
</function> (
<type>anymultirange
</type> )
21558 <returnvalue>boolean
</returnvalue>
21561 Does the multirange have no upper bound? (An upper bound of
21562 <literal>Infinity
</literal> returns false.)
21565 <literal>upper_inf('{(,)}'::datemultirange)
</literal>
21566 <returnvalue>t
</returnvalue>
21571 <entry role=
"func_table_entry"><para role=
"func_signature">
21573 <primary>range_merge
</primary>
21575 <function>range_merge
</function> (
<type>anymultirange
</type> )
21576 <returnvalue>anyrange
</returnvalue>
21579 Computes the smallest range that includes the entire multirange.
21582 <literal>range_merge('{[
1,
2), [
3,
4)}'::int4multirange)
</literal>
21583 <returnvalue>[
1,
4)
</returnvalue>
21588 <entry role=
"func_table_entry"><para role=
"func_signature">
21590 <primary>multirange (function)
</primary>
21592 <function>multirange
</function> (
<type>anyrange
</type> )
21593 <returnvalue>anymultirange
</returnvalue>
21596 Returns a multirange containing just the given range.
21599 <literal>multirange('[
1,
2)'::int4range)
</literal>
21600 <returnvalue>{[
1,
2)}
</returnvalue>
21605 <entry role=
"func_table_entry"><para role=
"func_signature">
21607 <primary>unnest
</primary>
21608 <secondary>for multirange
</secondary>
21610 <function>unnest
</function> (
<type>anymultirange
</type> )
21611 <returnvalue>setof anyrange
</returnvalue>
21614 Expands a multirange into a set of ranges in ascending order.
21617 <literal>unnest('{[
1,
2), [
3,
4)}'::int4multirange)
</literal>
21618 <returnvalue></returnvalue>
21630 The
<function>lower_inc
</function>,
<function>upper_inc
</function>,
21631 <function>lower_inf
</function>, and
<function>upper_inf
</function>
21632 functions all return false for an empty range or multirange.
21636 <sect1 id=
"functions-aggregate">
21637 <title>Aggregate Functions
</title>
21639 <indexterm zone=
"functions-aggregate">
21640 <primary>aggregate function
</primary>
21641 <secondary>built-in
</secondary>
21645 <firstterm>Aggregate functions
</firstterm> compute a single result
21646 from a set of input values. The built-in general-purpose aggregate
21647 functions are listed in
<xref linkend=
"functions-aggregate-table"/>
21648 while statistical aggregates are in
<xref
21649 linkend=
"functions-aggregate-statistics-table"/>.
21650 The built-in within-group ordered-set aggregate functions
21651 are listed in
<xref linkend=
"functions-orderedset-table"/>
21652 while the built-in within-group hypothetical-set ones are in
<xref
21653 linkend=
"functions-hypothetical-table"/>. Grouping operations,
21654 which are closely related to aggregate functions, are listed in
21655 <xref linkend=
"functions-grouping-table"/>.
21656 The special syntax considerations for aggregate
21657 functions are explained in
<xref linkend=
"syntax-aggregates"/>.
21658 Consult
<xref linkend=
"tutorial-agg"/> for additional introductory
21663 Aggregate functions that support
<firstterm>Partial Mode
</firstterm>
21664 are eligible to participate in various optimizations, such as parallel
21669 While all aggregates below accept an optional
21670 <literal>ORDER BY
</literal> clause (as outlined in
<xref
21671 linkend=
"syntax-aggregates"/>), the clause has only been added to
21672 aggregates whose output is affected by ordering.
21675 <table id=
"functions-aggregate-table">
21676 <title>General-Purpose Aggregate Functions
</title>
21678 <colspec colname=
"col1" colwidth=
"10*"/>
21679 <colspec colname=
"col2" colwidth=
"1*"/>
21682 <entry role=
"func_table_entry"><para role=
"func_signature">
21688 <entry>Partial Mode
</entry>
21694 <entry role=
"func_table_entry"><para role=
"func_signature">
21696 <primary>any_value
</primary>
21698 <function>any_value
</function> (
<type>anyelement
</type> )
21699 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
21702 Returns an arbitrary value from the non-null input values.
21708 <entry role=
"func_table_entry"><para role=
"func_signature">
21710 <primary>array_agg
</primary>
21712 <function>array_agg
</function> (
<type>anynonarray
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21713 <returnvalue>anyarray
</returnvalue>
21716 Collects all the input values, including nulls, into an array.
21722 <entry role=
"func_table_entry"><para role=
"func_signature">
21723 <function>array_agg
</function> (
<type>anyarray
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21724 <returnvalue>anyarray
</returnvalue>
21727 Concatenates all the input arrays into an array of one higher
21728 dimension. (The inputs must all have the same dimensionality, and
21729 cannot be empty or null.)
21735 <entry role=
"func_table_entry"><para role=
"func_signature">
21737 <primary>average
</primary>
21740 <primary>avg
</primary>
21742 <function>avg
</function> (
<type>smallint
</type> )
21743 <returnvalue>numeric
</returnvalue>
21745 <para role=
"func_signature">
21746 <function>avg
</function> (
<type>integer
</type> )
21747 <returnvalue>numeric
</returnvalue>
21749 <para role=
"func_signature">
21750 <function>avg
</function> (
<type>bigint
</type> )
21751 <returnvalue>numeric
</returnvalue>
21753 <para role=
"func_signature">
21754 <function>avg
</function> (
<type>numeric
</type> )
21755 <returnvalue>numeric
</returnvalue>
21757 <para role=
"func_signature">
21758 <function>avg
</function> (
<type>real
</type> )
21759 <returnvalue>double precision
</returnvalue>
21761 <para role=
"func_signature">
21762 <function>avg
</function> (
<type>double precision
</type> )
21763 <returnvalue>double precision
</returnvalue>
21765 <para role=
"func_signature">
21766 <function>avg
</function> (
<type>interval
</type> )
21767 <returnvalue>interval
</returnvalue>
21770 Computes the average (arithmetic mean) of all the non-null input
21777 <entry role=
"func_table_entry"><para role=
"func_signature">
21779 <primary>bit_and
</primary>
21781 <function>bit_and
</function> (
<type>smallint
</type> )
21782 <returnvalue>smallint
</returnvalue>
21784 <para role=
"func_signature">
21785 <function>bit_and
</function> (
<type>integer
</type> )
21786 <returnvalue>integer
</returnvalue>
21788 <para role=
"func_signature">
21789 <function>bit_and
</function> (
<type>bigint
</type> )
21790 <returnvalue>bigint
</returnvalue>
21792 <para role=
"func_signature">
21793 <function>bit_and
</function> (
<type>bit
</type> )
21794 <returnvalue>bit
</returnvalue>
21797 Computes the bitwise AND of all non-null input values.
21803 <entry role=
"func_table_entry"><para role=
"func_signature">
21805 <primary>bit_or
</primary>
21807 <function>bit_or
</function> (
<type>smallint
</type> )
21808 <returnvalue>smallint
</returnvalue>
21810 <para role=
"func_signature">
21811 <function>bit_or
</function> (
<type>integer
</type> )
21812 <returnvalue>integer
</returnvalue>
21814 <para role=
"func_signature">
21815 <function>bit_or
</function> (
<type>bigint
</type> )
21816 <returnvalue>bigint
</returnvalue>
21818 <para role=
"func_signature">
21819 <function>bit_or
</function> (
<type>bit
</type> )
21820 <returnvalue>bit
</returnvalue>
21823 Computes the bitwise OR of all non-null input values.
21829 <entry role=
"func_table_entry"><para role=
"func_signature">
21831 <primary>bit_xor
</primary>
21833 <function>bit_xor
</function> (
<type>smallint
</type> )
21834 <returnvalue>smallint
</returnvalue>
21836 <para role=
"func_signature">
21837 <function>bit_xor
</function> (
<type>integer
</type> )
21838 <returnvalue>integer
</returnvalue>
21840 <para role=
"func_signature">
21841 <function>bit_xor
</function> (
<type>bigint
</type> )
21842 <returnvalue>bigint
</returnvalue>
21844 <para role=
"func_signature">
21845 <function>bit_xor
</function> (
<type>bit
</type> )
21846 <returnvalue>bit
</returnvalue>
21849 Computes the bitwise exclusive OR of all non-null input values.
21850 Can be useful as a checksum for an unordered set of values.
21856 <entry role=
"func_table_entry"><para role=
"func_signature">
21858 <primary>bool_and
</primary>
21860 <function>bool_and
</function> (
<type>boolean
</type> )
21861 <returnvalue>boolean
</returnvalue>
21864 Returns true if all non-null input values are true, otherwise false.
21870 <entry role=
"func_table_entry"><para role=
"func_signature">
21872 <primary>bool_or
</primary>
21874 <function>bool_or
</function> (
<type>boolean
</type> )
21875 <returnvalue>boolean
</returnvalue>
21878 Returns true if any non-null input value is true, otherwise false.
21884 <entry role=
"func_table_entry"><para role=
"func_signature">
21886 <primary>count
</primary>
21888 <function>count
</function> (
<literal>*
</literal> )
21889 <returnvalue>bigint
</returnvalue>
21892 Computes the number of input rows.
21898 <entry role=
"func_table_entry"><para role=
"func_signature">
21899 <function>count
</function> (
<type>"any"</type> )
21900 <returnvalue>bigint
</returnvalue>
21903 Computes the number of input rows in which the input value is not
21910 <entry role=
"func_table_entry"><para role=
"func_signature">
21912 <primary>every
</primary>
21914 <function>every
</function> (
<type>boolean
</type> )
21915 <returnvalue>boolean
</returnvalue>
21918 This is the SQL standard's equivalent to
<function>bool_and
</function>.
21924 <entry role=
"func_table_entry"><para role=
"func_signature">
21926 <primary>json_agg
</primary>
21928 <function>json_agg
</function> (
<type>anyelement
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21929 <returnvalue>json
</returnvalue>
21931 <para role=
"func_signature">
21933 <primary>jsonb_agg
</primary>
21935 <function>jsonb_agg
</function> (
<type>anyelement
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
21936 <returnvalue>jsonb
</returnvalue>
21939 Collects all the input values, including nulls, into a JSON array.
21940 Values are converted to JSON as per
<function>to_json
</function>
21941 or
<function>to_jsonb
</function>.
21947 <entry role=
"func_table_entry"><para role=
"func_signature">
21949 <primary>json_agg_strict
</primary>
21951 <function>json_agg_strict
</function> (
<type>anyelement
</type> )
21952 <returnvalue>json
</returnvalue>
21954 <para role=
"func_signature">
21956 <primary>jsonb_agg_strict
</primary>
21958 <function>jsonb_agg_strict
</function> (
<type>anyelement
</type> )
21959 <returnvalue>jsonb
</returnvalue>
21962 Collects all the input values, skipping nulls, into a JSON array.
21963 Values are converted to JSON as per
<function>to_json
</function>
21964 or
<function>to_jsonb
</function>.
21970 <entry role=
"func_table_entry"><para role=
"func_signature">
21971 <indexterm><primary>json_arrayagg
</primary></indexterm>
21972 <function>json_arrayagg
</function> (
21973 <optional> <replaceable>value_expression
</replaceable> </optional>
21974 <optional> <literal>ORDER BY
</literal> <replaceable>sort_expression
</replaceable> </optional>
21975 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
21976 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
21979 Behaves in the same way as
<function>json_array
</function>
21980 but as an aggregate function so it only takes one
21981 <replaceable>value_expression
</replaceable> parameter.
21982 If
<literal>ABSENT ON NULL
</literal> is specified, any NULL
21983 values are omitted.
21984 If
<literal>ORDER BY
</literal> is specified, the elements will
21985 appear in the array in that order rather than in the input order.
21988 <literal>SELECT json_arrayagg(v) FROM (VALUES(
2),(
1)) t(v)
</literal>
21989 <returnvalue>[
2,
1]
</returnvalue>
21995 <entry role=
"func_table_entry"><para role=
"func_signature">
21996 <indexterm><primary>json_objectagg
</primary></indexterm>
21997 <function>json_objectagg
</function> (
21998 <optional> {
<replaceable>key_expression
</replaceable> {
<literal>VALUE
</literal> | ':' }
<replaceable>value_expression
</replaceable> }
</optional>
21999 <optional> {
<literal>NULL
</literal> |
<literal>ABSENT
</literal> }
<literal>ON NULL
</literal> </optional>
22000 <optional> {
<literal>WITH
</literal> |
<literal>WITHOUT
</literal> }
<literal>UNIQUE
</literal> <optional> <literal>KEYS
</literal> </optional> </optional>
22001 <optional> <literal>RETURNING
</literal> <replaceable>data_type
</replaceable> <optional> <literal>FORMAT JSON
</literal> <optional> <literal>ENCODING UTF8
</literal> </optional> </optional> </optional>)
22004 Behaves like
<function>json_object
</function><!-- xref -->, but as an
22005 aggregate function, so it only takes one
22006 <replaceable>key_expression
</replaceable> and one
22007 <replaceable>value_expression
</replaceable> parameter.
22010 <literal>SELECT json_objectagg(k:v) FROM (VALUES ('a'::text,current_date),('b',current_date +
1)) AS t(k,v)
</literal>
22011 <returnvalue>{
"a" :
"2022-05-10",
"b" :
"2022-05-11" }
</returnvalue>
22017 <entry role=
"func_table_entry"><para role=
"func_signature">
22019 <primary>json_object_agg
</primary>
22021 <function>json_object_agg
</function> (
<parameter>key
</parameter>
22022 <type>"any"</type>,
<parameter>value
</parameter>
22024 <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22025 <returnvalue>json
</returnvalue>
22027 <para role=
"func_signature">
22029 <primary>jsonb_object_agg
</primary>
22031 <function>jsonb_object_agg
</function> (
<parameter>key
</parameter>
22032 <type>"any"</type>,
<parameter>value
</parameter>
22034 <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22035 <returnvalue>jsonb
</returnvalue>
22038 Collects all the key/value pairs into a JSON object. Key arguments
22039 are coerced to text; value arguments are converted as per
22040 <function>to_json
</function> or
<function>to_jsonb
</function>.
22041 Values can be null, but keys cannot.
22047 <entry role=
"func_table_entry"><para role=
"func_signature">
22049 <primary>json_object_agg_strict
</primary>
22051 <function>json_object_agg_strict
</function> (
22052 <parameter>key
</parameter> <type>"any"</type>,
22053 <parameter>value
</parameter> <type>"any"</type> )
22054 <returnvalue>json
</returnvalue>
22056 <para role=
"func_signature">
22058 <primary>jsonb_object_agg_strict
</primary>
22060 <function>jsonb_object_agg_strict
</function> (
22061 <parameter>key
</parameter> <type>"any"</type>,
22062 <parameter>value
</parameter> <type>"any"</type> )
22063 <returnvalue>jsonb
</returnvalue>
22066 Collects all the key/value pairs into a JSON object. Key arguments
22067 are coerced to text; value arguments are converted as per
22068 <function>to_json
</function> or
<function>to_jsonb
</function>.
22069 The
<parameter>key
</parameter> can not be null. If the
22070 <parameter>value
</parameter> is null then the entry is skipped,
22076 <entry role=
"func_table_entry"><para role=
"func_signature">
22078 <primary>json_object_agg_unique
</primary>
22080 <function>json_object_agg_unique
</function> (
22081 <parameter>key
</parameter> <type>"any"</type>,
22082 <parameter>value
</parameter> <type>"any"</type> )
22083 <returnvalue>json
</returnvalue>
22085 <para role=
"func_signature">
22087 <primary>jsonb_object_agg_unique
</primary>
22089 <function>jsonb_object_agg_unique
</function> (
22090 <parameter>key
</parameter> <type>"any"</type>,
22091 <parameter>value
</parameter> <type>"any"</type> )
22092 <returnvalue>jsonb
</returnvalue>
22095 Collects all the key/value pairs into a JSON object. Key arguments
22096 are coerced to text; value arguments are converted as per
22097 <function>to_json
</function> or
<function>to_jsonb
</function>.
22098 Values can be null, but keys cannot.
22099 If there is a duplicate key an error is thrown.
22105 <entry role=
"func_table_entry"><para role=
"func_signature">
22107 <primary>json_object_agg_unique_strict
</primary>
22109 <function>json_object_agg_unique_strict
</function> (
22110 <parameter>key
</parameter> <type>"any"</type>,
22111 <parameter>value
</parameter> <type>"any"</type> )
22112 <returnvalue>json
</returnvalue>
22114 <para role=
"func_signature">
22116 <primary>jsonb_object_agg_unique_strict
</primary>
22118 <function>jsonb_object_agg_unique_strict
</function> (
22119 <parameter>key
</parameter> <type>"any"</type>,
22120 <parameter>value
</parameter> <type>"any"</type> )
22121 <returnvalue>jsonb
</returnvalue>
22124 Collects all the key/value pairs into a JSON object. Key arguments
22125 are coerced to text; value arguments are converted as per
22126 <function>to_json
</function> or
<function>to_jsonb
</function>.
22127 The
<parameter>key
</parameter> can not be null. If the
22128 <parameter>value
</parameter> is null then the entry is skipped.
22129 If there is a duplicate key an error is thrown.
22135 <entry role=
"func_table_entry"><para role=
"func_signature">
22137 <primary>max
</primary>
22139 <function>max
</function> (
<replaceable>see text
</replaceable> )
22140 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
22143 Computes the maximum of the non-null input
22144 values. Available for any numeric, string, date/time, or enum type,
22145 as well as
<type>bytea
</type>,
<type>inet
</type>,
<type>interval
</type>,
22146 <type>money
</type>,
<type>oid
</type>,
<type>pg_lsn
</type>,
22147 <type>tid
</type>,
<type>xid8
</type>,
22148 and also arrays and composite types containing sortable data types.
22154 <entry role=
"func_table_entry"><para role=
"func_signature">
22156 <primary>min
</primary>
22158 <function>min
</function> (
<replaceable>see text
</replaceable> )
22159 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
22162 Computes the minimum of the non-null input
22163 values. Available for any numeric, string, date/time, or enum type,
22164 as well as
<type>bytea
</type>,
<type>inet
</type>,
<type>interval
</type>,
22165 <type>money
</type>,
<type>oid
</type>,
<type>pg_lsn
</type>,
22166 <type>tid
</type>,
<type>xid8
</type>,
22167 and also arrays and composite types containing sortable data types.
22173 <entry role=
"func_table_entry"><para role=
"func_signature">
22175 <primary>range_agg
</primary>
22177 <function>range_agg
</function> (
<parameter>value
</parameter>
22178 <type>anyrange
</type> )
22179 <returnvalue>anymultirange
</returnvalue>
22181 <para role=
"func_signature">
22182 <function>range_agg
</function> (
<parameter>value
</parameter>
22183 <type>anymultirange
</type> )
22184 <returnvalue>anymultirange
</returnvalue>
22187 Computes the union of the non-null input values.
22193 <entry role=
"func_table_entry"><para role=
"func_signature">
22195 <primary>range_intersect_agg
</primary>
22197 <function>range_intersect_agg
</function> (
<parameter>value
</parameter>
22198 <type>anyrange
</type> )
22199 <returnvalue>anyrange
</returnvalue>
22201 <para role=
"func_signature">
22202 <function>range_intersect_agg
</function> (
<parameter>value
</parameter>
22203 <type>anymultirange
</type> )
22204 <returnvalue>anymultirange
</returnvalue>
22207 Computes the intersection of the non-null input values.
22213 <entry role=
"func_table_entry"><para role=
"func_signature">
22215 <primary>string_agg
</primary>
22217 <function>string_agg
</function> (
<parameter>value
</parameter>
22218 <type>text
</type>,
<parameter>delimiter
</parameter> <type>text
</type> )
22219 <returnvalue>text
</returnvalue>
22221 <para role=
"func_signature">
22222 <function>string_agg
</function> (
<parameter>value
</parameter>
22223 <type>bytea
</type>,
<parameter>delimiter
</parameter> <type>bytea
</type>
22224 <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22225 <returnvalue>bytea
</returnvalue>
22228 Concatenates the non-null input values into a string. Each value
22229 after the first is preceded by the
22230 corresponding
<parameter>delimiter
</parameter> (if it's not null).
22236 <entry role=
"func_table_entry"><para role=
"func_signature">
22238 <primary>sum
</primary>
22240 <function>sum
</function> (
<type>smallint
</type> )
22241 <returnvalue>bigint
</returnvalue>
22243 <para role=
"func_signature">
22244 <function>sum
</function> (
<type>integer
</type> )
22245 <returnvalue>bigint
</returnvalue>
22247 <para role=
"func_signature">
22248 <function>sum
</function> (
<type>bigint
</type> )
22249 <returnvalue>numeric
</returnvalue>
22251 <para role=
"func_signature">
22252 <function>sum
</function> (
<type>numeric
</type> )
22253 <returnvalue>numeric
</returnvalue>
22255 <para role=
"func_signature">
22256 <function>sum
</function> (
<type>real
</type> )
22257 <returnvalue>real
</returnvalue>
22259 <para role=
"func_signature">
22260 <function>sum
</function> (
<type>double precision
</type> )
22261 <returnvalue>double precision
</returnvalue>
22263 <para role=
"func_signature">
22264 <function>sum
</function> (
<type>interval
</type> )
22265 <returnvalue>interval
</returnvalue>
22267 <para role=
"func_signature">
22268 <function>sum
</function> (
<type>money
</type> )
22269 <returnvalue>money
</returnvalue>
22272 Computes the sum of the non-null input values.
22278 <entry role=
"func_table_entry"><para role=
"func_signature">
22280 <primary>xmlagg
</primary>
22282 <function>xmlagg
</function> (
<type>xml
</type> <literal>ORDER BY
</literal> <literal>input_sort_columns
</literal> )
22283 <returnvalue>xml
</returnvalue>
22286 Concatenates the non-null XML input values (see
22287 <xref linkend=
"functions-xml-xmlagg"/>).
22296 It should be noted that except for
<function>count
</function>,
22297 these functions return a null value when no rows are selected. In
22298 particular,
<function>sum
</function> of no rows returns null, not
22299 zero as one might expect, and
<function>array_agg
</function>
22300 returns null rather than an empty array when there are no input
22301 rows. The
<function>coalesce
</function> function can be used to
22302 substitute zero or an empty array for null when necessary.
22306 The aggregate functions
<function>array_agg
</function>,
22307 <function>json_agg
</function>,
<function>jsonb_agg
</function>,
22308 <function>json_agg_strict
</function>,
<function>jsonb_agg_strict
</function>,
22309 <function>json_object_agg
</function>,
<function>jsonb_object_agg
</function>,
22310 <function>json_object_agg_strict
</function>,
<function>jsonb_object_agg_strict
</function>,
22311 <function>json_object_agg_unique
</function>,
<function>jsonb_object_agg_unique
</function>,
22312 <function>json_object_agg_unique_strict
</function>,
22313 <function>jsonb_object_agg_unique_strict
</function>,
22314 <function>string_agg
</function>,
22315 and
<function>xmlagg
</function>, as well as similar user-defined
22316 aggregate functions, produce meaningfully different result values
22317 depending on the order of the input values. This ordering is
22318 unspecified by default, but can be controlled by writing an
22319 <literal>ORDER BY
</literal> clause within the aggregate call, as shown in
22320 <xref linkend=
"syntax-aggregates"/>.
22321 Alternatively, supplying the input values from a sorted subquery
22322 will usually work. For example:
22325 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
22328 Beware that this approach can fail if the outer query level contains
22329 additional processing, such as a join, because that might cause the
22330 subquery's output to be reordered before the aggregate is computed.
22335 <primary>ANY
</primary>
22338 <primary>SOME
</primary>
22341 The boolean aggregates
<function>bool_and
</function> and
22342 <function>bool_or
</function> correspond to the standard SQL aggregates
22343 <function>every
</function> and
<function>any
</function> or
22344 <function>some
</function>.
22345 <productname>PostgreSQL
</productname>
22346 supports
<function>every
</function>, but not
<function>any
</function>
22347 or
<function>some
</function>, because there is an ambiguity built into
22348 the standard syntax:
22350 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
22352 Here
<function>ANY
</function> can be considered either as introducing
22353 a subquery, or as being an aggregate function, if the subquery
22354 returns one row with a Boolean value.
22355 Thus the standard name cannot be given to these aggregates.
22361 Users accustomed to working with other SQL database management
22362 systems might be disappointed by the performance of the
22363 <function>count
</function> aggregate when it is applied to the
22364 entire table. A query like:
22366 SELECT count(*) FROM sometable;
22368 will require effort proportional to the size of the table:
22369 <productname>PostgreSQL
</productname> will need to scan either the
22370 entire table or the entirety of an index that includes all rows in
22376 <xref linkend=
"functions-aggregate-statistics-table"/> shows
22377 aggregate functions typically used in statistical analysis.
22378 (These are separated out merely to avoid cluttering the listing
22379 of more-commonly-used aggregates.) Functions shown as
22380 accepting
<replaceable>numeric_type
</replaceable> are available for all
22381 the types
<type>smallint
</type>,
<type>integer
</type>,
22382 <type>bigint
</type>,
<type>numeric
</type>,
<type>real
</type>,
22383 and
<type>double precision
</type>.
22384 Where the description mentions
22385 <parameter>N
</parameter>, it means the
22386 number of input rows for which all the input expressions are non-null.
22387 In all cases, null is returned if the computation is meaningless,
22388 for example when
<parameter>N
</parameter> is zero.
22392 <primary>statistics
</primary>
22395 <primary>linear regression
</primary>
22398 <table id=
"functions-aggregate-statistics-table">
22399 <title>Aggregate Functions for Statistics
</title>
22401 <colspec colname=
"col1" colwidth=
"10*"/>
22402 <colspec colname=
"col2" colwidth=
"1*"/>
22405 <entry role=
"func_table_entry"><para role=
"func_signature">
22411 <entry>Partial Mode
</entry>
22417 <entry role=
"func_table_entry"><para role=
"func_signature">
22419 <primary>correlation
</primary>
22422 <primary>corr
</primary>
22424 <function>corr
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22425 <returnvalue>double precision
</returnvalue>
22428 Computes the correlation coefficient.
22434 <entry role=
"func_table_entry"><para role=
"func_signature">
22436 <primary>covariance
</primary>
22437 <secondary>population
</secondary>
22440 <primary>covar_pop
</primary>
22442 <function>covar_pop
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22443 <returnvalue>double precision
</returnvalue>
22446 Computes the population covariance.
22452 <entry role=
"func_table_entry"><para role=
"func_signature">
22454 <primary>covariance
</primary>
22455 <secondary>sample
</secondary>
22458 <primary>covar_samp
</primary>
22460 <function>covar_samp
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22461 <returnvalue>double precision
</returnvalue>
22464 Computes the sample covariance.
22470 <entry role=
"func_table_entry"><para role=
"func_signature">
22472 <primary>regr_avgx
</primary>
22474 <function>regr_avgx
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22475 <returnvalue>double precision
</returnvalue>
22478 Computes the average of the independent variable,
22479 <literal>sum(
<parameter>X
</parameter>)/
<parameter>N
</parameter></literal>.
22485 <entry role=
"func_table_entry"><para role=
"func_signature">
22487 <primary>regr_avgy
</primary>
22489 <function>regr_avgy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22490 <returnvalue>double precision
</returnvalue>
22493 Computes the average of the dependent variable,
22494 <literal>sum(
<parameter>Y
</parameter>)/
<parameter>N
</parameter></literal>.
22500 <entry role=
"func_table_entry"><para role=
"func_signature">
22502 <primary>regr_count
</primary>
22504 <function>regr_count
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22505 <returnvalue>bigint
</returnvalue>
22508 Computes the number of rows in which both inputs are non-null.
22514 <entry role=
"func_table_entry"><para role=
"func_signature">
22516 <primary>regression intercept
</primary>
22519 <primary>regr_intercept
</primary>
22521 <function>regr_intercept
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22522 <returnvalue>double precision
</returnvalue>
22525 Computes the y-intercept of the least-squares-fit linear equation
22527 (
<parameter>X
</parameter>,
<parameter>Y
</parameter>) pairs.
22533 <entry role=
"func_table_entry"><para role=
"func_signature">
22535 <primary>regr_r2
</primary>
22537 <function>regr_r2
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22538 <returnvalue>double precision
</returnvalue>
22541 Computes the square of the correlation coefficient.
22547 <entry role=
"func_table_entry"><para role=
"func_signature">
22549 <primary>regression slope
</primary>
22552 <primary>regr_slope
</primary>
22554 <function>regr_slope
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22555 <returnvalue>double precision
</returnvalue>
22558 Computes the slope of the least-squares-fit linear equation determined
22559 by the (
<parameter>X
</parameter>,
<parameter>Y
</parameter>)
22566 <entry role=
"func_table_entry"><para role=
"func_signature">
22568 <primary>regr_sxx
</primary>
22570 <function>regr_sxx
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22571 <returnvalue>double precision
</returnvalue>
22574 Computes the
<quote>sum of squares
</quote> of the independent
22576 <literal>sum(
<parameter>X
</parameter>^
2) - sum(
<parameter>X
</parameter>)^
2/
<parameter>N
</parameter></literal>.
22582 <entry role=
"func_table_entry"><para role=
"func_signature">
22584 <primary>regr_sxy
</primary>
22586 <function>regr_sxy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22587 <returnvalue>double precision
</returnvalue>
22590 Computes the
<quote>sum of products
</quote> of independent times
22591 dependent variables,
22592 <literal>sum(
<parameter>X
</parameter>*
<parameter>Y
</parameter>) - sum(
<parameter>X
</parameter>) * sum(
<parameter>Y
</parameter>)/
<parameter>N
</parameter></literal>.
22598 <entry role=
"func_table_entry"><para role=
"func_signature">
22600 <primary>regr_syy
</primary>
22602 <function>regr_syy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
22603 <returnvalue>double precision
</returnvalue>
22606 Computes the
<quote>sum of squares
</quote> of the dependent
22608 <literal>sum(
<parameter>Y
</parameter>^
2) - sum(
<parameter>Y
</parameter>)^
2/
<parameter>N
</parameter></literal>.
22614 <entry role=
"func_table_entry"><para role=
"func_signature">
22616 <primary>standard deviation
</primary>
22619 <primary>stddev
</primary>
22621 <function>stddev
</function> (
<replaceable>numeric_type
</replaceable> )
22622 <returnvalue></returnvalue> <type>double precision
</type>
22623 for
<type>real
</type> or
<type>double precision
</type>,
22624 otherwise
<type>numeric
</type>
22627 This is a historical alias for
<function>stddev_samp
</function>.
22633 <entry role=
"func_table_entry"><para role=
"func_signature">
22635 <primary>standard deviation
</primary>
22636 <secondary>population
</secondary>
22639 <primary>stddev_pop
</primary>
22641 <function>stddev_pop
</function> (
<replaceable>numeric_type
</replaceable> )
22642 <returnvalue></returnvalue> <type>double precision
</type>
22643 for
<type>real
</type> or
<type>double precision
</type>,
22644 otherwise
<type>numeric
</type>
22647 Computes the population standard deviation of the input values.
22653 <entry role=
"func_table_entry"><para role=
"func_signature">
22655 <primary>standard deviation
</primary>
22656 <secondary>sample
</secondary>
22659 <primary>stddev_samp
</primary>
22661 <function>stddev_samp
</function> (
<replaceable>numeric_type
</replaceable> )
22662 <returnvalue></returnvalue> <type>double precision
</type>
22663 for
<type>real
</type> or
<type>double precision
</type>,
22664 otherwise
<type>numeric
</type>
22667 Computes the sample standard deviation of the input values.
22673 <entry role=
"func_table_entry"><para role=
"func_signature">
22675 <primary>variance
</primary>
22677 <function>variance
</function> (
<replaceable>numeric_type
</replaceable> )
22678 <returnvalue></returnvalue> <type>double precision
</type>
22679 for
<type>real
</type> or
<type>double precision
</type>,
22680 otherwise
<type>numeric
</type>
22683 This is a historical alias for
<function>var_samp
</function>.
22689 <entry role=
"func_table_entry"><para role=
"func_signature">
22691 <primary>variance
</primary>
22692 <secondary>population
</secondary>
22695 <primary>var_pop
</primary>
22697 <function>var_pop
</function> (
<replaceable>numeric_type
</replaceable> )
22698 <returnvalue></returnvalue> <type>double precision
</type>
22699 for
<type>real
</type> or
<type>double precision
</type>,
22700 otherwise
<type>numeric
</type>
22703 Computes the population variance of the input values (square of the
22704 population standard deviation).
22710 <entry role=
"func_table_entry"><para role=
"func_signature">
22712 <primary>variance
</primary>
22713 <secondary>sample
</secondary>
22716 <primary>var_samp
</primary>
22718 <function>var_samp
</function> (
<replaceable>numeric_type
</replaceable> )
22719 <returnvalue></returnvalue> <type>double precision
</type>
22720 for
<type>real
</type> or
<type>double precision
</type>,
22721 otherwise
<type>numeric
</type>
22724 Computes the sample variance of the input values (square of the sample
22725 standard deviation).
22734 <xref linkend=
"functions-orderedset-table"/> shows some
22735 aggregate functions that use the
<firstterm>ordered-set aggregate
</firstterm>
22736 syntax. These functions are sometimes referred to as
<quote>inverse
22737 distribution
</quote> functions. Their aggregated input is introduced by
22738 <literal>ORDER BY
</literal>, and they may also take a
<firstterm>direct
22739 argument
</firstterm> that is not aggregated, but is computed only once.
22740 All these functions ignore null values in their aggregated input.
22741 For those that take a
<parameter>fraction
</parameter> parameter, the
22742 fraction value must be between
0 and
1; an error is thrown if not.
22743 However, a null
<parameter>fraction
</parameter> value simply produces a
22748 <primary>ordered-set aggregate
</primary>
22749 <secondary>built-in
</secondary>
22752 <primary>inverse distribution
</primary>
22755 <table id=
"functions-orderedset-table">
22756 <title>Ordered-Set Aggregate Functions
</title>
22758 <colspec colname=
"col1" colwidth=
"10*"/>
22759 <colspec colname=
"col2" colwidth=
"1*"/>
22762 <entry role=
"func_table_entry"><para role=
"func_signature">
22768 <entry>Partial Mode
</entry>
22774 <entry role=
"func_table_entry"><para role=
"func_signature">
22776 <primary>mode
</primary>
22777 <secondary>statistical
</secondary>
22779 <function>mode
</function> ()
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
22780 <returnvalue>anyelement
</returnvalue>
22783 Computes the
<firstterm>mode
</firstterm>, the most frequent
22784 value of the aggregated argument (arbitrarily choosing the first one
22785 if there are multiple equally-frequent values). The aggregated
22786 argument must be of a sortable type.
22792 <entry role=
"func_table_entry"><para role=
"func_signature">
22794 <primary>percentile
</primary>
22795 <secondary>continuous
</secondary>
22797 <function>percentile_cont
</function> (
<parameter>fraction
</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>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>interval
</type> )
22802 <returnvalue>interval
</returnvalue>
22805 Computes the
<firstterm>continuous percentile
</firstterm>, a value
22806 corresponding to the specified
<parameter>fraction
</parameter>
22807 within the ordered set of aggregated argument values. This will
22808 interpolate between adjacent input items if needed.
22814 <entry role=
"func_table_entry"><para role=
"func_signature">
22815 <function>percentile_cont
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>double precision
</type> )
22816 <returnvalue>double precision[]
</returnvalue>
22818 <para role=
"func_signature">
22819 <function>percentile_cont
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>interval
</type> )
22820 <returnvalue>interval[]
</returnvalue>
22823 Computes multiple continuous percentiles. The result is an array of
22824 the same dimensions as the
<parameter>fractions
</parameter>
22825 parameter, with each non-null element replaced by the (possibly
22826 interpolated) value corresponding to that percentile.
22832 <entry role=
"func_table_entry"><para role=
"func_signature">
22834 <primary>percentile
</primary>
22835 <secondary>discrete
</secondary>
22837 <function>percentile_disc
</function> (
<parameter>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
22838 <returnvalue>anyelement
</returnvalue>
22841 Computes the
<firstterm>discrete percentile
</firstterm>, the first
22842 value within the ordered set of aggregated argument values whose
22843 position in the ordering equals or exceeds the
22844 specified
<parameter>fraction
</parameter>. The aggregated
22845 argument must be of a sortable type.
22851 <entry role=
"func_table_entry"><para role=
"func_signature">
22852 <function>percentile_disc
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
22853 <returnvalue>anyarray
</returnvalue>
22856 Computes multiple discrete percentiles. The result is an array of the
22857 same dimensions as the
<parameter>fractions
</parameter> parameter,
22858 with each non-null element replaced by the input value corresponding
22859 to that percentile.
22860 The aggregated argument must be of a sortable type.
22869 <primary>hypothetical-set aggregate
</primary>
22870 <secondary>built-in
</secondary>
22874 Each of the
<quote>hypothetical-set
</quote> aggregates listed in
22875 <xref linkend=
"functions-hypothetical-table"/> is associated with a
22876 window function of the same name defined in
22877 <xref linkend=
"functions-window"/>. In each case, the aggregate's result
22878 is the value that the associated window function would have
22879 returned for the
<quote>hypothetical
</quote> row constructed from
22880 <replaceable>args
</replaceable>, if such a row had been added to the sorted
22881 group of rows represented by the
<replaceable>sorted_args
</replaceable>.
22882 For each of these functions, the list of direct arguments
22883 given in
<replaceable>args
</replaceable> must match the number and types of
22884 the aggregated arguments given in
<replaceable>sorted_args
</replaceable>.
22885 Unlike most built-in aggregates, these aggregates are not strict, that is
22886 they do not drop input rows containing nulls. Null values sort according
22887 to the rule specified in the
<literal>ORDER BY
</literal> clause.
22890 <table id=
"functions-hypothetical-table">
22891 <title>Hypothetical-Set Aggregate Functions
</title>
22893 <colspec colname=
"col1" colwidth=
"10*"/>
22894 <colspec colname=
"col2" colwidth=
"1*"/>
22897 <entry role=
"func_table_entry"><para role=
"func_signature">
22903 <entry>Partial Mode
</entry>
22909 <entry role=
"func_table_entry"><para role=
"func_signature">
22911 <primary>rank
</primary>
22912 <secondary>hypothetical
</secondary>
22914 <function>rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22915 <returnvalue>bigint
</returnvalue>
22918 Computes the rank of the hypothetical row, with gaps; that is, the row
22919 number of the first row in its peer group.
22925 <entry role=
"func_table_entry"><para role=
"func_signature">
22927 <primary>dense_rank
</primary>
22928 <secondary>hypothetical
</secondary>
22930 <function>dense_rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22931 <returnvalue>bigint
</returnvalue>
22934 Computes the rank of the hypothetical row, without gaps; this function
22935 effectively counts peer groups.
22941 <entry role=
"func_table_entry"><para role=
"func_signature">
22943 <primary>percent_rank
</primary>
22944 <secondary>hypothetical
</secondary>
22946 <function>percent_rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22947 <returnvalue>double precision
</returnvalue>
22950 Computes the relative rank of the hypothetical row, that is
22951 (
<function>rank
</function> -
1) / (total rows -
1).
22952 The value thus ranges from
0 to
1 inclusive.
22958 <entry role=
"func_table_entry"><para role=
"func_signature">
22960 <primary>cume_dist
</primary>
22961 <secondary>hypothetical
</secondary>
22963 <function>cume_dist
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
22964 <returnvalue>double precision
</returnvalue>
22967 Computes the cumulative distribution, that is (number of rows
22968 preceding or peers with hypothetical row) / (total rows). The value
22969 thus ranges from
1/
<parameter>N
</parameter> to
1.
22977 <table id=
"functions-grouping-table">
22978 <title>Grouping Operations
</title>
22982 <entry role=
"func_table_entry"><para role=
"func_signature">
22993 <entry role=
"func_table_entry"><para role=
"func_signature">
22995 <primary>GROUPING
</primary>
22997 <function>GROUPING
</function> (
<replaceable>group_by_expression(s)
</replaceable> )
22998 <returnvalue>integer
</returnvalue>
23001 Returns a bit mask indicating which
<literal>GROUP BY
</literal>
23002 expressions are not included in the current grouping set.
23003 Bits are assigned with the rightmost argument corresponding to the
23004 least-significant bit; each bit is
0 if the corresponding expression
23005 is included in the grouping criteria of the grouping set generating
23006 the current result row, and
1 if it is not included.
23014 The grouping operations shown in
23015 <xref linkend=
"functions-grouping-table"/> are used in conjunction with
23016 grouping sets (see
<xref linkend=
"queries-grouping-sets"/>) to distinguish
23017 result rows. The arguments to the
<literal>GROUPING
</literal> function
23018 are not actually evaluated, but they must exactly match expressions given
23019 in the
<literal>GROUP BY
</literal> clause of the associated query level.
23022 <prompt>=
></prompt> <userinput>SELECT * FROM items_sold;
</userinput>
23023 make | model | sales
23024 -------+-------+-------
23031 <prompt>=
></prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);
</userinput>
23032 make | model | grouping | sum
23033 -------+-------+----------+-----
23035 Foo | Tour |
0 |
20
23036 Bar | City |
0 |
15
23037 Bar | Sport |
0 |
5
23043 Here, the
<literal>grouping
</literal> value
<literal>0</literal> in the
23044 first four rows shows that those have been grouped normally, over both the
23045 grouping columns. The value
<literal>1</literal> indicates
23046 that
<literal>model
</literal> was not grouped by in the next-to-last two
23047 rows, and the value
<literal>3</literal> indicates that
23048 neither
<literal>make
</literal> nor
<literal>model
</literal> was grouped
23049 by in the last row (which therefore is an aggregate over all the input
23055 <sect1 id=
"functions-window">
23056 <title>Window Functions
</title>
23058 <indexterm zone=
"functions-window">
23059 <primary>window function
</primary>
23060 <secondary>built-in
</secondary>
23064 <firstterm>Window functions
</firstterm> provide the ability to perform
23065 calculations across sets of rows that are related to the current query
23066 row. See
<xref linkend=
"tutorial-window"/> for an introduction to this
23067 feature, and
<xref linkend=
"syntax-window-functions"/> for syntax
23072 The built-in window functions are listed in
23073 <xref linkend=
"functions-window-table"/>. Note that these functions
23074 <emphasis>must
</emphasis> be invoked using window function syntax, i.e., an
23075 <literal>OVER
</literal> clause is required.
23079 In addition to these functions, any built-in or user-defined
23080 ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates)
23081 can be used as a window function; see
23082 <xref linkend=
"functions-aggregate"/> for a list of the built-in aggregates.
23083 Aggregate functions act as window functions only when an
<literal>OVER
</literal>
23084 clause follows the call; otherwise they act as plain aggregates
23085 and return a single row for the entire set.
23088 <table id=
"functions-window-table">
23089 <title>General-Purpose Window Functions
</title>
23093 <entry role=
"func_table_entry"><para role=
"func_signature">
23104 <entry role=
"func_table_entry"><para role=
"func_signature">
23106 <primary>row_number
</primary>
23108 <function>row_number
</function> ()
23109 <returnvalue>bigint
</returnvalue>
23112 Returns the number of the current row within its partition, counting
23118 <entry role=
"func_table_entry"><para role=
"func_signature">
23120 <primary>rank
</primary>
23122 <function>rank
</function> ()
23123 <returnvalue>bigint
</returnvalue>
23126 Returns the rank of the current row, with gaps; that is,
23127 the
<function>row_number
</function> of the first row in its peer
23133 <entry role=
"func_table_entry"><para role=
"func_signature">
23135 <primary>dense_rank
</primary>
23137 <function>dense_rank
</function> ()
23138 <returnvalue>bigint
</returnvalue>
23141 Returns the rank of the current row, without gaps; this function
23142 effectively counts peer groups.
23147 <entry role=
"func_table_entry"><para role=
"func_signature">
23149 <primary>percent_rank
</primary>
23151 <function>percent_rank
</function> ()
23152 <returnvalue>double precision
</returnvalue>
23155 Returns the relative rank of the current row, that is
23156 (
<function>rank
</function> -
1) / (total partition rows -
1).
23157 The value thus ranges from
0 to
1 inclusive.
23162 <entry role=
"func_table_entry"><para role=
"func_signature">
23164 <primary>cume_dist
</primary>
23166 <function>cume_dist
</function> ()
23167 <returnvalue>double precision
</returnvalue>
23170 Returns the cumulative distribution, that is (number of partition rows
23171 preceding or peers with current row) / (total partition rows).
23172 The value thus ranges from
1/
<parameter>N
</parameter> to
1.
23177 <entry role=
"func_table_entry"><para role=
"func_signature">
23179 <primary>ntile
</primary>
23181 <function>ntile
</function> (
<parameter>num_buckets
</parameter> <type>integer
</type> )
23182 <returnvalue>integer
</returnvalue>
23185 Returns an integer ranging from
1 to the argument value, dividing the
23186 partition as equally as possible.
23191 <entry role=
"func_table_entry"><para role=
"func_signature">
23193 <primary>lag
</primary>
23195 <function>lag
</function> (
<parameter>value
</parameter> <type>anycompatible
</type>
23196 <optional>,
<parameter>offset
</parameter> <type>integer
</type>
23197 <optional>,
<parameter>default
</parameter> <type>anycompatible
</type> </optional></optional> )
23198 <returnvalue>anycompatible
</returnvalue>
23201 Returns
<parameter>value
</parameter> evaluated at
23202 the row that is
<parameter>offset
</parameter>
23203 rows before the current row within the partition; if there is no such
23204 row, instead returns
<parameter>default
</parameter>
23205 (which must be of a type compatible with
23206 <parameter>value
</parameter>).
23207 Both
<parameter>offset
</parameter> and
23208 <parameter>default
</parameter> are evaluated
23209 with respect to the current row. If omitted,
23210 <parameter>offset
</parameter> defaults to
1 and
23211 <parameter>default
</parameter> to
<literal>NULL
</literal>.
23216 <entry role=
"func_table_entry"><para role=
"func_signature">
23218 <primary>lead
</primary>
23220 <function>lead
</function> (
<parameter>value
</parameter> <type>anycompatible
</type>
23221 <optional>,
<parameter>offset
</parameter> <type>integer
</type>
23222 <optional>,
<parameter>default
</parameter> <type>anycompatible
</type> </optional></optional> )
23223 <returnvalue>anycompatible
</returnvalue>
23226 Returns
<parameter>value
</parameter> evaluated at
23227 the row that is
<parameter>offset
</parameter>
23228 rows after the current row within the partition; if there is no such
23229 row, instead returns
<parameter>default
</parameter>
23230 (which must be of a type compatible with
23231 <parameter>value
</parameter>).
23232 Both
<parameter>offset
</parameter> and
23233 <parameter>default
</parameter> are evaluated
23234 with respect to the current row. If omitted,
23235 <parameter>offset
</parameter> defaults to
1 and
23236 <parameter>default
</parameter> to
<literal>NULL
</literal>.
23241 <entry role=
"func_table_entry"><para role=
"func_signature">
23243 <primary>first_value
</primary>
23245 <function>first_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type> )
23246 <returnvalue>anyelement
</returnvalue>
23249 Returns
<parameter>value
</parameter> evaluated
23250 at the row that is the first row of the window frame.
23255 <entry role=
"func_table_entry"><para role=
"func_signature">
23257 <primary>last_value
</primary>
23259 <function>last_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type> )
23260 <returnvalue>anyelement
</returnvalue>
23263 Returns
<parameter>value
</parameter> evaluated
23264 at the row that is the last row of the window frame.
23269 <entry role=
"func_table_entry"><para role=
"func_signature">
23271 <primary>nth_value
</primary>
23273 <function>nth_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type>,
<parameter>n
</parameter> <type>integer
</type> )
23274 <returnvalue>anyelement
</returnvalue>
23277 Returns
<parameter>value
</parameter> evaluated
23278 at the row that is the
<parameter>n
</parameter>'th
23279 row of the window frame (counting from
1);
23280 returns
<literal>NULL
</literal> if there is no such row.
23288 All of the functions listed in
23289 <xref linkend=
"functions-window-table"/> depend on the sort ordering
23290 specified by the
<literal>ORDER BY
</literal> clause of the associated window
23291 definition. Rows that are not distinct when considering only the
23292 <literal>ORDER BY
</literal> columns are said to be
<firstterm>peers
</firstterm>.
23293 The four ranking functions (including
<function>cume_dist
</function>) are
23294 defined so that they give the same answer for all rows of a peer group.
23298 Note that
<function>first_value
</function>,
<function>last_value
</function>, and
23299 <function>nth_value
</function> consider only the rows within the
<quote>window
23300 frame
</quote>, which by default contains the rows from the start of the
23301 partition through the last peer of the current row. This is
23302 likely to give unhelpful results for
<function>last_value
</function> and
23303 sometimes also
<function>nth_value
</function>. You can redefine the frame by
23304 adding a suitable frame specification (
<literal>RANGE
</literal>,
23305 <literal>ROWS
</literal> or
<literal>GROUPS
</literal>) to
23306 the
<literal>OVER
</literal> clause.
23307 See
<xref linkend=
"syntax-window-functions"/> for more information
23308 about frame specifications.
23312 When an aggregate function is used as a window function, it aggregates
23313 over the rows within the current row's window frame.
23314 An aggregate used with
<literal>ORDER BY
</literal> and the default window frame
23315 definition produces a
<quote>running sum
</quote> type of behavior, which may or
23316 may not be what's wanted. To obtain
23317 aggregation over the whole partition, omit
<literal>ORDER BY
</literal> or use
23318 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
</literal>.
23319 Other frame specifications can be used to obtain other effects.
23324 The SQL standard defines a
<literal>RESPECT NULLS
</literal> or
23325 <literal>IGNORE NULLS
</literal> option for
<function>lead
</function>,
<function>lag
</function>,
23326 <function>first_value
</function>,
<function>last_value
</function>, and
23327 <function>nth_value
</function>. This is not implemented in
23328 <productname>PostgreSQL
</productname>: the behavior is always the
23329 same as the standard's default, namely
<literal>RESPECT NULLS
</literal>.
23330 Likewise, the standard's
<literal>FROM FIRST
</literal> or
<literal>FROM LAST
</literal>
23331 option for
<function>nth_value
</function> is not implemented: only the
23332 default
<literal>FROM FIRST
</literal> behavior is supported. (You can achieve
23333 the result of
<literal>FROM LAST
</literal> by reversing the
<literal>ORDER BY
</literal>
23340 <sect1 id=
"functions-merge-support">
23341 <title>Merge Support Functions
</title>
23344 <primary>MERGE
</primary>
23345 <secondary>RETURNING
</secondary>
23349 <productname>PostgreSQL
</productname> includes one merge support function
23350 that may be used in the
<literal>RETURNING
</literal> list of a
23351 <xref linkend=
"sql-merge"/> command to identify the action taken for each
23352 row; see
<xref linkend=
"functions-merge-support-table"/>.
23355 <table id=
"functions-merge-support-table">
23356 <title>Merge Support Functions
</title>
23361 <entry role=
"func_table_entry"><para role=
"func_signature">
23372 <entry id=
"merge-action" role=
"func_table_entry"><para role=
"func_signature">
23374 <primary>merge_action
</primary>
23376 <function>merge_action
</function> ( )
23377 <returnvalue>text
</returnvalue>
23380 Returns the merge action command executed for the current row. This
23381 will be
<literal>'INSERT'
</literal>,
<literal>'UPDATE'
</literal>, or
23382 <literal>'DELETE'
</literal>.
23392 MERGE INTO products p
23393 USING stock s ON p.product_id = s.product_id
23394 WHEN MATCHED AND s.quantity
> 0 THEN
23395 UPDATE SET in_stock = true, quantity = s.quantity
23397 UPDATE SET in_stock = false, quantity =
0
23398 WHEN NOT MATCHED THEN
23399 INSERT (product_id, in_stock, quantity)
23400 VALUES (s.product_id, true, s.quantity)
23401 RETURNING merge_action(), p.*;
23403 merge_action | product_id | in_stock | quantity
23404 --------------+------------+----------+----------
23405 UPDATE |
1001 | t |
50
23406 UPDATE |
1002 | f |
0
23407 INSERT |
1003 | t |
10
23412 Note that this function can only be used in the
<literal>RETURNING
</literal>
23413 list of a
<command>MERGE
</command> command. It is an error to use it in any
23414 other part of a query.
23419 <sect1 id=
"functions-subquery">
23420 <title>Subquery Expressions
</title>
23423 <primary>EXISTS
</primary>
23427 <primary>IN
</primary>
23431 <primary>NOT IN
</primary>
23435 <primary>ANY
</primary>
23439 <primary>ALL
</primary>
23443 <primary>SOME
</primary>
23447 <primary>subquery
</primary>
23451 This section describes the
<acronym>SQL
</acronym>-compliant subquery
23452 expressions available in
<productname>PostgreSQL
</productname>.
23453 All of the expression forms documented in this section return
23454 Boolean (true/false) results.
23457 <sect2 id=
"functions-subquery-exists">
23458 <title><literal>EXISTS
</literal></title>
23461 EXISTS (
<replaceable>subquery
</replaceable>)
23465 The argument of
<token>EXISTS
</token> is an arbitrary
<command>SELECT
</command> statement,
23466 or
<firstterm>subquery
</firstterm>. The
23467 subquery is evaluated to determine whether it returns any rows.
23468 If it returns at least one row, the result of
<token>EXISTS
</token> is
23469 <quote>true
</quote>; if the subquery returns no rows, the result of
<token>EXISTS
</token>
23470 is
<quote>false
</quote>.
23474 The subquery can refer to variables from the surrounding query,
23475 which will act as constants during any one evaluation of the subquery.
23479 The subquery will generally only be executed long enough to determine
23480 whether at least one row is returned, not all the way to completion.
23481 It is unwise to write a subquery that has side effects (such as
23482 calling sequence functions); whether the side effects occur
23483 might be unpredictable.
23487 Since the result depends only on whether any rows are returned,
23488 and not on the contents of those rows, the output list of the
23489 subquery is normally unimportant. A common coding convention is
23490 to write all
<literal>EXISTS
</literal> tests in the form
23491 <literal>EXISTS(SELECT
1 WHERE ...)
</literal>. There are exceptions to
23492 this rule however, such as subqueries that use
<token>INTERSECT
</token>.
23496 This simple example is like an inner join on
<literal>col2
</literal>, but
23497 it produces at most one output row for each
<literal>tab1
</literal> row,
23498 even if there are several matching
<literal>tab2
</literal> rows:
23502 WHERE EXISTS (SELECT
1 FROM tab2 WHERE col2 = tab1.col2);
23507 <sect2 id=
"functions-subquery-in">
23508 <title><literal>IN
</literal></title>
23511 <replaceable>expression
</replaceable> IN (
<replaceable>subquery
</replaceable>)
23515 The right-hand side is a parenthesized
23516 subquery, which must return exactly one column. The left-hand expression
23517 is evaluated and compared to each row of the subquery result.
23518 The result of
<token>IN
</token> is
<quote>true
</quote> if any equal subquery row is found.
23519 The result is
<quote>false
</quote> if no equal row is found (including the
23520 case where the subquery returns no rows).
23524 Note that if the left-hand expression yields null, or if there are
23525 no equal right-hand values and at least one right-hand row yields
23526 null, the result of the
<token>IN
</token> construct will be null, not false.
23527 This is in accordance with SQL's normal rules for Boolean combinations
23532 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23533 be evaluated completely.
23537 <replaceable>row_constructor
</replaceable> IN (
<replaceable>subquery
</replaceable>)
23541 The left-hand side of this form of
<token>IN
</token> is a row constructor,
23542 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23543 The right-hand side is a parenthesized
23544 subquery, which must return exactly as many columns as there are
23545 expressions in the left-hand row. The left-hand expressions are
23546 evaluated and compared row-wise to each row of the subquery result.
23547 The result of
<token>IN
</token> is
<quote>true
</quote> if any equal subquery row is found.
23548 The result is
<quote>false
</quote> if no equal row is found (including the
23549 case where the subquery returns no rows).
23553 As usual, null values in the rows are combined per
23554 the normal rules of SQL Boolean expressions. Two rows are considered
23555 equal if all their corresponding members are non-null and equal; the rows
23556 are unequal if any corresponding members are non-null and unequal;
23557 otherwise the result of that row comparison is unknown (null).
23558 If all the per-row results are either unequal or null, with at least one
23559 null, then the result of
<token>IN
</token> is null.
23563 <sect2 id=
"functions-subquery-notin">
23564 <title><literal>NOT IN
</literal></title>
23567 <replaceable>expression
</replaceable> NOT IN (
<replaceable>subquery
</replaceable>)
23571 The right-hand side is a parenthesized
23572 subquery, which must return exactly one column. The left-hand expression
23573 is evaluated and compared to each row of the subquery result.
23574 The result of
<token>NOT IN
</token> is
<quote>true
</quote> if only unequal subquery rows
23575 are found (including the case where the subquery returns no rows).
23576 The result is
<quote>false
</quote> if any equal row is found.
23580 Note that if the left-hand expression yields null, or if there are
23581 no equal right-hand values and at least one right-hand row yields
23582 null, the result of the
<token>NOT IN
</token> construct will be null, not true.
23583 This is in accordance with SQL's normal rules for Boolean combinations
23588 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23589 be evaluated completely.
23593 <replaceable>row_constructor
</replaceable> NOT IN (
<replaceable>subquery
</replaceable>)
23597 The left-hand side of this form of
<token>NOT IN
</token> is a row constructor,
23598 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23599 The right-hand side is a parenthesized
23600 subquery, which must return exactly as many columns as there are
23601 expressions in the left-hand row. The left-hand expressions are
23602 evaluated and compared row-wise to each row of the subquery result.
23603 The result of
<token>NOT IN
</token> is
<quote>true
</quote> if only unequal subquery rows
23604 are found (including the case where the subquery returns no rows).
23605 The result is
<quote>false
</quote> if any equal row is found.
23609 As usual, null values in the rows are combined per
23610 the normal rules of SQL Boolean expressions. Two rows are considered
23611 equal if all their corresponding members are non-null and equal; the rows
23612 are unequal if any corresponding members are non-null and unequal;
23613 otherwise the result of that row comparison is unknown (null).
23614 If all the per-row results are either unequal or null, with at least one
23615 null, then the result of
<token>NOT IN
</token> is null.
23619 <sect2 id=
"functions-subquery-any-some">
23620 <title><literal>ANY
</literal>/
<literal>SOME
</literal></title>
23623 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>subquery
</replaceable>)
23624 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>subquery
</replaceable>)
23628 The right-hand side is a parenthesized
23629 subquery, which must return exactly one column. The left-hand expression
23630 is evaluated and compared to each row of the subquery result using the
23631 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23633 The result of
<token>ANY
</token> is
<quote>true
</quote> if any true result is obtained.
23634 The result is
<quote>false
</quote> if no true result is found (including the
23635 case where the subquery returns no rows).
23639 <token>SOME
</token> is a synonym for
<token>ANY
</token>.
23640 <token>IN
</token> is equivalent to
<literal>= ANY
</literal>.
23644 Note that if there are no successes and at least one right-hand row yields
23645 null for the operator's result, the result of the
<token>ANY
</token> construct
23646 will be null, not false.
23647 This is in accordance with SQL's normal rules for Boolean combinations
23652 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23653 be evaluated completely.
23657 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>subquery
</replaceable>)
23658 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>subquery
</replaceable>)
23662 The left-hand side of this form of
<token>ANY
</token> is a row constructor,
23663 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23664 The right-hand side is a parenthesized
23665 subquery, which must return exactly as many columns as there are
23666 expressions in the left-hand row. The left-hand expressions are
23667 evaluated and compared row-wise to each row of the subquery result,
23668 using the given
<replaceable>operator
</replaceable>.
23669 The result of
<token>ANY
</token> is
<quote>true
</quote> if the comparison
23670 returns true for any subquery row.
23671 The result is
<quote>false
</quote> if the comparison returns false for every
23672 subquery row (including the case where the subquery returns no
23674 The result is NULL if no comparison with a subquery row returns true,
23675 and at least one comparison returns NULL.
23679 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
23680 of a row constructor comparison.
23684 <sect2 id=
"functions-subquery-all">
23685 <title><literal>ALL
</literal></title>
23688 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>subquery
</replaceable>)
23692 The right-hand side is a parenthesized
23693 subquery, which must return exactly one column. The left-hand expression
23694 is evaluated and compared to each row of the subquery result using the
23695 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23697 The result of
<token>ALL
</token> is
<quote>true
</quote> if all rows yield true
23698 (including the case where the subquery returns no rows).
23699 The result is
<quote>false
</quote> if any false result is found.
23700 The result is NULL if no comparison with a subquery row returns false,
23701 and at least one comparison returns NULL.
23705 <token>NOT IN
</token> is equivalent to
<literal><> ALL
</literal>.
23709 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
23710 be evaluated completely.
23714 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>subquery
</replaceable>)
23718 The left-hand side of this form of
<token>ALL
</token> is a row constructor,
23719 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23720 The right-hand side is a parenthesized
23721 subquery, which must return exactly as many columns as there are
23722 expressions in the left-hand row. The left-hand expressions are
23723 evaluated and compared row-wise to each row of the subquery result,
23724 using the given
<replaceable>operator
</replaceable>.
23725 The result of
<token>ALL
</token> is
<quote>true
</quote> if the comparison
23726 returns true for all subquery rows (including the
23727 case where the subquery returns no rows).
23728 The result is
<quote>false
</quote> if the comparison returns false for any
23730 The result is NULL if no comparison with a subquery row returns false,
23731 and at least one comparison returns NULL.
23735 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
23736 of a row constructor comparison.
23740 <sect2 id=
"functions-subquery-single-row-comp">
23741 <title>Single-Row Comparison
</title>
23743 <indexterm zone=
"functions-subquery">
23744 <primary>comparison
</primary>
23745 <secondary>subquery result row
</secondary>
23749 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> (
<replaceable>subquery
</replaceable>)
23753 The left-hand side is a row constructor,
23754 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23755 The right-hand side is a parenthesized subquery, which must return exactly
23756 as many columns as there are expressions in the left-hand row. Furthermore,
23757 the subquery cannot return more than one row. (If it returns zero rows,
23758 the result is taken to be null.) The left-hand side is evaluated and
23759 compared row-wise to the single subquery result row.
23763 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
23764 of a row constructor comparison.
23770 <sect1 id=
"functions-comparisons">
23771 <title>Row and Array Comparisons
</title>
23774 <primary>IN
</primary>
23778 <primary>NOT IN
</primary>
23782 <primary>ANY
</primary>
23786 <primary>ALL
</primary>
23790 <primary>SOME
</primary>
23794 <primary>composite type
</primary>
23795 <secondary>comparison
</secondary>
23799 <primary>row-wise comparison
</primary>
23803 <primary>comparison
</primary>
23804 <secondary>composite type
</secondary>
23808 <primary>comparison
</primary>
23809 <secondary>row constructor
</secondary>
23813 <primary>IS DISTINCT FROM
</primary>
23817 <primary>IS NOT DISTINCT FROM
</primary>
23821 This section describes several specialized constructs for making
23822 multiple comparisons between groups of values. These forms are
23823 syntactically related to the subquery forms of the previous section,
23824 but do not involve subqueries.
23825 The forms involving array subexpressions are
23826 <productname>PostgreSQL
</productname> extensions; the rest are
23827 <acronym>SQL
</acronym>-compliant.
23828 All of the expression forms documented in this section return
23829 Boolean (true/false) results.
23832 <sect2 id=
"functions-comparisons-in-scalar">
23833 <title><literal>IN
</literal></title>
23836 <replaceable>expression
</replaceable> IN (
<replaceable>value
</replaceable> <optional>, ...
</optional>)
23840 The right-hand side is a parenthesized list
23841 of expressions. The result is
<quote>true
</quote> if the left-hand expression's
23842 result is equal to any of the right-hand expressions. This is a shorthand
23846 <replaceable>expression
</replaceable> =
<replaceable>value1
</replaceable>
23848 <replaceable>expression
</replaceable> =
<replaceable>value2
</replaceable>
23855 Note that if the left-hand expression yields null, or if there are
23856 no equal right-hand values and at least one right-hand expression yields
23857 null, the result of the
<token>IN
</token> construct will be null, not false.
23858 This is in accordance with SQL's normal rules for Boolean combinations
23863 <sect2 id=
"functions-comparisons-not-in">
23864 <title><literal>NOT IN
</literal></title>
23867 <replaceable>expression
</replaceable> NOT IN (
<replaceable>value
</replaceable> <optional>, ...
</optional>)
23871 The right-hand side is a parenthesized list
23872 of expressions. The result is
<quote>true
</quote> if the left-hand expression's
23873 result is unequal to all of the right-hand expressions. This is a shorthand
23877 <replaceable>expression
</replaceable> <> <replaceable>value1
</replaceable>
23879 <replaceable>expression
</replaceable> <> <replaceable>value2
</replaceable>
23886 Note that if the left-hand expression yields null, or if there are
23887 no equal right-hand values and at least one right-hand expression yields
23888 null, the result of the
<token>NOT IN
</token> construct will be null, not true
23889 as one might naively expect.
23890 This is in accordance with SQL's normal rules for Boolean combinations
23896 <literal>x NOT IN y
</literal> is equivalent to
<literal>NOT (x IN y)
</literal> in all
23897 cases. However, null values are much more likely to trip up the novice when
23898 working with
<token>NOT IN
</token> than when working with
<token>IN
</token>.
23899 It is best to express your condition positively if possible.
23904 <sect2 id=
"functions-comparisons-any-some">
23905 <title><literal>ANY
</literal>/
<literal>SOME
</literal> (array)
</title>
23908 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>array expression
</replaceable>)
23909 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>array expression
</replaceable>)
23913 The right-hand side is a parenthesized expression, which must yield an
23915 The left-hand expression
23916 is evaluated and compared to each element of the array using the
23917 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23919 The result of
<token>ANY
</token> is
<quote>true
</quote> if any true result is obtained.
23920 The result is
<quote>false
</quote> if no true result is found (including the
23921 case where the array has zero elements).
23925 If the array expression yields a null array, the result of
23926 <token>ANY
</token> will be null. If the left-hand expression yields null,
23927 the result of
<token>ANY
</token> is ordinarily null (though a non-strict
23928 comparison operator could possibly yield a different result).
23929 Also, if the right-hand array contains any null elements and no true
23930 comparison result is obtained, the result of
<token>ANY
</token>
23931 will be null, not false (again, assuming a strict comparison operator).
23932 This is in accordance with SQL's normal rules for Boolean combinations
23937 <token>SOME
</token> is a synonym for
<token>ANY
</token>.
23941 <sect2 id=
"functions-comparisons-all">
23942 <title><literal>ALL
</literal> (array)
</title>
23945 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>array expression
</replaceable>)
23949 The right-hand side is a parenthesized expression, which must yield an
23951 The left-hand expression
23952 is evaluated and compared to each element of the array using the
23953 given
<replaceable>operator
</replaceable>, which must yield a Boolean
23955 The result of
<token>ALL
</token> is
<quote>true
</quote> if all comparisons yield true
23956 (including the case where the array has zero elements).
23957 The result is
<quote>false
</quote> if any false result is found.
23961 If the array expression yields a null array, the result of
23962 <token>ALL
</token> will be null. If the left-hand expression yields null,
23963 the result of
<token>ALL
</token> is ordinarily null (though a non-strict
23964 comparison operator could possibly yield a different result).
23965 Also, if the right-hand array contains any null elements and no false
23966 comparison result is obtained, the result of
<token>ALL
</token>
23967 will be null, not true (again, assuming a strict comparison operator).
23968 This is in accordance with SQL's normal rules for Boolean combinations
23973 <sect2 id=
"row-wise-comparison">
23974 <title>Row Constructor Comparison
</title>
23977 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> <replaceable>row_constructor
</replaceable>
23981 Each side is a row constructor,
23982 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
23983 The two row constructors must have the same number of fields.
23984 The given
<replaceable>operator
</replaceable> is applied to each pair
23985 of corresponding fields. (Since the fields could be of different
23986 types, this means that a different specific operator could be selected
23988 All the selected operators must be members of some B-tree operator
23989 class, or be the negator of an
<literal>=
</literal> member of a B-tree
23990 operator class, meaning that row constructor comparison is only
23991 possible when the
<replaceable>operator
</replaceable> is
23992 <literal>=
</literal>,
23993 <literal><></literal>,
23994 <literal><</literal>,
23995 <literal><=
</literal>,
23996 <literal>></literal>, or
23997 <literal>>=
</literal>,
23998 or has semantics similar to one of these.
24002 The
<literal>=
</literal> and
<literal><></literal> cases work slightly differently
24003 from the others. Two rows are considered
24004 equal if all their corresponding members are non-null and equal; the rows
24005 are unequal if any corresponding members are non-null and unequal;
24006 otherwise the result of the row comparison is unknown (null).
24010 For the
<literal><</literal>,
<literal><=
</literal>,
<literal>></literal> and
24011 <literal>>=
</literal> cases, the row elements are compared left-to-right,
24012 stopping as soon as an unequal or null pair of elements is found.
24013 If either of this pair of elements is null, the result of the
24014 row comparison is unknown (null); otherwise comparison of this pair
24015 of elements determines the result. For example,
24016 <literal>ROW(
1,
2,NULL)
< ROW(
1,
3,
0)
</literal>
24017 yields true, not null, because the third pair of elements are not
24022 <replaceable>row_constructor
</replaceable> IS DISTINCT FROM
<replaceable>row_constructor
</replaceable>
24026 This construct is similar to a
<literal><></literal> row comparison,
24027 but it does not yield null for null inputs. Instead, any null value is
24028 considered unequal to (distinct from) any non-null value, and any two
24029 nulls are considered equal (not distinct). Thus the result will
24030 either be true or false, never null.
24034 <replaceable>row_constructor
</replaceable> IS NOT DISTINCT FROM
<replaceable>row_constructor
</replaceable>
24038 This construct is similar to a
<literal>=
</literal> row comparison,
24039 but it does not yield null for null inputs. Instead, any null value is
24040 considered unequal to (distinct from) any non-null value, and any two
24041 nulls are considered equal (not distinct). Thus the result will always
24042 be either true or false, never null.
24047 <sect2 id=
"composite-type-comparison">
24048 <title>Composite Type Comparison
</title>
24051 <replaceable>record
</replaceable> <replaceable>operator
</replaceable> <replaceable>record
</replaceable>
24055 The SQL specification requires row-wise comparison to return NULL if the
24056 result depends on comparing two NULL values or a NULL and a non-NULL.
24057 <productname>PostgreSQL
</productname> does this only when comparing the
24058 results of two row constructors (as in
24059 <xref linkend=
"row-wise-comparison"/>) or comparing a row constructor
24060 to the output of a subquery (as in
<xref linkend=
"functions-subquery"/>).
24061 In other contexts where two composite-type values are compared, two
24062 NULL field values are considered equal, and a NULL is considered larger
24063 than a non-NULL. This is necessary in order to have consistent sorting
24064 and indexing behavior for composite types.
24068 Each side is evaluated and they are compared row-wise. Composite type
24069 comparisons are allowed when the
<replaceable>operator
</replaceable> is
24070 <literal>=
</literal>,
24071 <literal><></literal>,
24072 <literal><</literal>,
24073 <literal><=
</literal>,
24074 <literal>></literal> or
24075 <literal>>=
</literal>,
24076 or has semantics similar to one of these. (To be specific, an operator
24077 can be a row comparison operator if it is a member of a B-tree operator
24078 class, or is the negator of the
<literal>=
</literal> member of a B-tree operator
24079 class.) The default behavior of the above operators is the same as for
24080 <literal>IS [ NOT ] DISTINCT FROM
</literal> for row constructors (see
24081 <xref linkend=
"row-wise-comparison"/>).
24085 To support matching of rows which include elements without a default
24086 B-tree operator class, the following operators are defined for composite
24088 <literal>*=
</literal>,
24089 <literal>*
<></literal>,
24090 <literal>*
<</literal>,
24091 <literal>*
<=
</literal>,
24092 <literal>*
></literal>, and
24093 <literal>*
>=
</literal>.
24094 These operators compare the internal binary representation of the two
24095 rows. Two rows might have a different binary representation even
24096 though comparisons of the two rows with the equality operator is true.
24097 The ordering of rows under these comparison operators is deterministic
24098 but not otherwise meaningful. These operators are used internally
24099 for materialized views and might be useful for other specialized
24100 purposes such as replication and B-Tree deduplication (see
<xref
24101 linkend=
"btree-deduplication"/>). They are not intended to be
24102 generally useful for writing queries, though.
24107 <sect1 id=
"functions-srf">
24108 <title>Set Returning Functions
</title>
24110 <indexterm zone=
"functions-srf">
24111 <primary>set returning functions
</primary>
24112 <secondary>functions
</secondary>
24116 This section describes functions that possibly return more than one row.
24117 The most widely used functions in this class are series generating
24118 functions, as detailed in
<xref linkend=
"functions-srf-series"/> and
24119 <xref linkend=
"functions-srf-subscripts"/>. Other, more specialized
24120 set-returning functions are described elsewhere in this manual.
24121 See
<xref linkend=
"queries-tablefunctions"/> for ways to combine multiple
24122 set-returning functions.
24125 <table id=
"functions-srf-series">
24126 <title>Series Generating Functions
</title>
24130 <entry role=
"func_table_entry"><para role=
"func_signature">
24141 <entry role=
"func_table_entry"><para role=
"func_signature">
24143 <primary>generate_series
</primary>
24145 <function>generate_series
</function> (
<parameter>start
</parameter> <type>integer
</type>,
<parameter>stop
</parameter> <type>integer
</type> <optional>,
<parameter>step
</parameter> <type>integer
</type> </optional> )
24146 <returnvalue>setof integer
</returnvalue>
24148 <para role=
"func_signature">
24149 <function>generate_series
</function> (
<parameter>start
</parameter> <type>bigint
</type>,
<parameter>stop
</parameter> <type>bigint
</type> <optional>,
<parameter>step
</parameter> <type>bigint
</type> </optional> )
24150 <returnvalue>setof bigint
</returnvalue>
24152 <para role=
"func_signature">
24153 <function>generate_series
</function> (
<parameter>start
</parameter> <type>numeric
</type>,
<parameter>stop
</parameter> <type>numeric
</type> <optional>,
<parameter>step
</parameter> <type>numeric
</type> </optional> )
24154 <returnvalue>setof numeric
</returnvalue>
24157 Generates a series of values from
<parameter>start
</parameter>
24158 to
<parameter>stop
</parameter>, with a step size
24159 of
<parameter>step
</parameter>.
<parameter>step
</parameter>
24165 <entry role=
"func_table_entry"><para role=
"func_signature">
24166 <function>generate_series
</function> (
<parameter>start
</parameter> <type>timestamp
</type>,
<parameter>stop
</parameter> <type>timestamp
</type>,
<parameter>step
</parameter> <type>interval
</type> )
24167 <returnvalue>setof timestamp
</returnvalue>
24169 <para role=
"func_signature">
24170 <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> )
24171 <returnvalue>setof timestamp with time zone
</returnvalue>
24174 Generates a series of values from
<parameter>start
</parameter>
24175 to
<parameter>stop
</parameter>, with a step size
24176 of
<parameter>step
</parameter>.
24177 In the timezone-aware form, times of day and daylight-savings
24178 adjustments are computed according to the time zone named by
24179 the
<parameter>timezone
</parameter> argument, or the current
24180 <xref linkend=
"guc-timezone"/> setting if that is omitted.
24188 When
<parameter>step
</parameter> is positive, zero rows are returned if
24189 <parameter>start
</parameter> is greater than
<parameter>stop
</parameter>.
24190 Conversely, when
<parameter>step
</parameter> is negative, zero rows are
24191 returned if
<parameter>start
</parameter> is less than
<parameter>stop
</parameter>.
24192 Zero rows are also returned if any input is
<literal>NULL
</literal>.
24194 for
<parameter>step
</parameter> to be zero. Some examples follow:
24196 SELECT * FROM generate_series(
2,
4);
24204 SELECT * FROM generate_series(
5,
1,-
2);
24212 SELECT * FROM generate_series(
4,
3);
24217 SELECT generate_series(
1.1,
4,
1.3);
24225 -- this example relies on the date-plus-integer operator:
24226 SELECT current_date + s.a AS dates FROM generate_series(
0,
14,
7) AS s(a);
24234 SELECT * FROM generate_series('
2008-
03-
01 00:
00'::timestamp,
24235 '
2008-
03-
04 12:
00', '
10 hours');
24237 ---------------------
24238 2008-
03-
01 00:
00:
00
24239 2008-
03-
01 10:
00:
00
24240 2008-
03-
01 20:
00:
00
24241 2008-
03-
02 06:
00:
00
24242 2008-
03-
02 16:
00:
00
24243 2008-
03-
03 02:
00:
00
24244 2008-
03-
03 12:
00:
00
24245 2008-
03-
03 22:
00:
00
24246 2008-
03-
04 08:
00:
00
24249 -- this example assumes that TimeZone is set to UTC; note the DST transition:
24250 SELECT * FROM generate_series('
2001-
10-
22 00:
00 -
04:
00'::timestamptz,
24251 '
2001-
11-
01 00:
00 -
05:
00'::timestamptz,
24252 '
1 day'::interval, 'America/New_York');
24254 ------------------------
24255 2001-
10-
22 04:
00:
00+
00
24256 2001-
10-
23 04:
00:
00+
00
24257 2001-
10-
24 04:
00:
00+
00
24258 2001-
10-
25 04:
00:
00+
00
24259 2001-
10-
26 04:
00:
00+
00
24260 2001-
10-
27 04:
00:
00+
00
24261 2001-
10-
28 04:
00:
00+
00
24262 2001-
10-
29 05:
00:
00+
00
24263 2001-
10-
30 05:
00:
00+
00
24264 2001-
10-
31 05:
00:
00+
00
24265 2001-
11-
01 05:
00:
00+
00
24270 <table id=
"functions-srf-subscripts">
24271 <title>Subscript Generating Functions
</title>
24275 <entry role=
"func_table_entry"><para role=
"func_signature">
24286 <entry role=
"func_table_entry"><para role=
"func_signature">
24288 <primary>generate_subscripts
</primary>
24290 <function>generate_subscripts
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>dim
</parameter> <type>integer
</type> )
24291 <returnvalue>setof integer
</returnvalue>
24294 Generates a series comprising the valid subscripts of
24295 the
<parameter>dim
</parameter>'th dimension of the given array.
24300 <entry role=
"func_table_entry"><para role=
"func_signature">
24301 <function>generate_subscripts
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>dim
</parameter> <type>integer
</type>,
<parameter>reverse
</parameter> <type>boolean
</type> )
24302 <returnvalue>setof integer
</returnvalue>
24305 Generates a series comprising the valid subscripts of
24306 the
<parameter>dim
</parameter>'th dimension of the given array.
24307 When
<parameter>reverse
</parameter> is true, returns the series in
24316 <function>generate_subscripts
</function> is a convenience function that generates
24317 the set of valid subscripts for the specified dimension of the given
24319 Zero rows are returned for arrays that do not have the requested dimension,
24320 or if any input is
<literal>NULL
</literal>.
24321 Some examples follow:
24324 SELECT generate_subscripts('{NULL,
1,NULL,
2}'::int[],
1) AS s;
24333 -- presenting an array, the subscript and the subscripted
24334 -- value requires a subquery:
24335 SELECT * FROM arrays;
24337 --------------------
24342 SELECT a AS array, s AS subscript, a[s] AS value
24343 FROM (SELECT generate_subscripts(a,
1) AS s, a FROM arrays) foo;
24344 array | subscript | value
24345 ---------------+-----------+-------
24348 {
100,
200,
300} |
1 |
100
24349 {
100,
200,
300} |
2 |
200
24350 {
100,
200,
300} |
3 |
300
24353 -- unnest a
2D array:
24354 CREATE OR REPLACE FUNCTION unnest2(anyarray)
24355 RETURNS SETOF anyelement AS $$
24357 from generate_subscripts($
1,
1) g1(i),
24358 generate_subscripts($
1,
2) g2(j);
24359 $$ LANGUAGE sql IMMUTABLE;
24361 SELECT * FROM unnest2(ARRAY[[
1,
2],[
3,
4]]);
24373 <primary>ordinality
</primary>
24377 When a function in the
<literal>FROM
</literal> clause is suffixed
24378 by
<literal>WITH ORDINALITY
</literal>, a
<type>bigint
</type> column is
24379 appended to the function's output column(s), which starts from
1 and
24380 increments by
1 for each row of the function's output.
24381 This is most useful in the case of set returning
24382 functions such as
<function>unnest()
</function>.
24385 -- set returning function WITH ORDINALITY:
24386 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
24388 -----------------+----
24391 postmaster.opts |
3
24393 postgresql.conf |
5
24414 <sect1 id=
"functions-info">
24415 <title>System Information Functions and Operators
</title>
24418 The functions described in this section are used to obtain various
24419 information about a
<productname>PostgreSQL
</productname> installation.
24422 <sect2 id=
"functions-info-session">
24423 <title>Session Information Functions
</title>
24426 <xref linkend=
"functions-info-session-table"/> shows several
24427 functions that extract session and system information.
24431 In addition to the functions listed in this section, there are a number of
24432 functions related to the statistics system that also provide system
24433 information. See
<xref linkend=
"monitoring-stats-functions"/> for more
24437 <table id=
"functions-info-session-table">
24438 <title>Session Information Functions
</title>
24442 <entry role=
"func_table_entry"><para role=
"func_signature">
24453 <entry role=
"func_table_entry"><para role=
"func_signature">
24455 <primary>current_catalog
</primary>
24457 <function>current_catalog
</function>
24458 <returnvalue>name
</returnvalue>
24460 <para role=
"func_signature">
24462 <primary>current_database
</primary>
24464 <function>current_database
</function> ()
24465 <returnvalue>name
</returnvalue>
24468 Returns the name of the current database. (Databases are
24469 called
<quote>catalogs
</quote> in the SQL standard,
24470 so
<function>current_catalog
</function> is the standard's
24476 <entry role=
"func_table_entry"><para role=
"func_signature">
24478 <primary>current_query
</primary>
24480 <function>current_query
</function> ()
24481 <returnvalue>text
</returnvalue>
24484 Returns the text of the currently executing query, as submitted
24485 by the client (which might contain more than one statement).
24490 <entry role=
"func_table_entry"><para role=
"func_signature">
24492 <primary>current_role
</primary>
24494 <function>current_role
</function>
24495 <returnvalue>name
</returnvalue>
24498 This is equivalent to
<function>current_user
</function>.
24503 <entry role=
"func_table_entry"><para role=
"func_signature">
24505 <primary>current_schema
</primary>
24508 <primary>schema
</primary>
24509 <secondary>current
</secondary>
24511 <function>current_schema
</function>
24512 <returnvalue>name
</returnvalue>
24514 <para role=
"func_signature">
24515 <function>current_schema
</function> ()
24516 <returnvalue>name
</returnvalue>
24519 Returns the name of the schema that is first in the search path (or a
24520 null value if the search path is empty). This is the schema that will
24521 be used for any tables or other named objects that are created without
24522 specifying a target schema.
24527 <entry role=
"func_table_entry"><para role=
"func_signature">
24529 <primary>current_schemas
</primary>
24532 <primary>search path
</primary>
24533 <secondary>current
</secondary>
24535 <function>current_schemas
</function> (
<parameter>include_implicit
</parameter> <type>boolean
</type> )
24536 <returnvalue>name[]
</returnvalue>
24539 Returns an array of the names of all schemas presently in the
24540 effective search path, in their priority order. (Items in the current
24541 <xref linkend=
"guc-search-path"/> setting that do not correspond to
24542 existing, searchable schemas are omitted.) If the Boolean argument
24543 is
<literal>true
</literal>, then implicitly-searched system schemas
24544 such as
<literal>pg_catalog
</literal> are included in the result.
24549 <entry role=
"func_table_entry"><para role=
"func_signature">
24551 <primary>current_user
</primary>
24554 <primary>user
</primary>
24555 <secondary>current
</secondary>
24557 <function>current_user
</function>
24558 <returnvalue>name
</returnvalue>
24561 Returns the user name of the current execution context.
24566 <entry role=
"func_table_entry"><para role=
"func_signature">
24568 <primary>inet_client_addr
</primary>
24570 <function>inet_client_addr
</function> ()
24571 <returnvalue>inet
</returnvalue>
24574 Returns the IP address of the current client,
24575 or
<literal>NULL
</literal> if the current connection is via a
24576 Unix-domain socket.
24581 <entry role=
"func_table_entry"><para role=
"func_signature">
24583 <primary>inet_client_port
</primary>
24585 <function>inet_client_port
</function> ()
24586 <returnvalue>integer
</returnvalue>
24589 Returns the IP port number of the current client,
24590 or
<literal>NULL
</literal> if the current connection is via a
24591 Unix-domain socket.
24596 <entry role=
"func_table_entry"><para role=
"func_signature">
24598 <primary>inet_server_addr
</primary>
24600 <function>inet_server_addr
</function> ()
24601 <returnvalue>inet
</returnvalue>
24604 Returns the IP address on which the server accepted the current
24606 or
<literal>NULL
</literal> if the current connection is via a
24607 Unix-domain socket.
24612 <entry role=
"func_table_entry"><para role=
"func_signature">
24614 <primary>inet_server_port
</primary>
24616 <function>inet_server_port
</function> ()
24617 <returnvalue>integer
</returnvalue>
24620 Returns the IP port number on which the server accepted the current
24622 or
<literal>NULL
</literal> if the current connection is via a
24623 Unix-domain socket.
24628 <entry role=
"func_table_entry"><para role=
"func_signature">
24630 <primary>pg_backend_pid
</primary>
24632 <function>pg_backend_pid
</function> ()
24633 <returnvalue>integer
</returnvalue>
24636 Returns the process ID of the server process attached to the current
24642 <entry role=
"func_table_entry"><para role=
"func_signature">
24644 <primary>pg_blocking_pids
</primary>
24646 <function>pg_blocking_pids
</function> (
<type>integer
</type> )
24647 <returnvalue>integer[]
</returnvalue>
24650 Returns an array of the process ID(s) of the sessions that are
24651 blocking the server process with the specified process ID from
24652 acquiring a lock, or an empty array if there is no such server process
24653 or it is not blocked.
24656 One server process blocks another if it either holds a lock that
24657 conflicts with the blocked process's lock request (hard block), or is
24658 waiting for a lock that would conflict with the blocked process's lock
24659 request and is ahead of it in the wait queue (soft block). When using
24660 parallel queries the result always lists client-visible process IDs
24661 (that is,
<function>pg_backend_pid
</function> results) even if the
24662 actual lock is held or awaited by a child worker process. As a result
24663 of that, there may be duplicated PIDs in the result. Also note that
24664 when a prepared transaction holds a conflicting lock, it will be
24665 represented by a zero process ID.
24668 Frequent calls to this function could have some impact on database
24669 performance, because it needs exclusive access to the lock manager's
24670 shared state for a short time.
24675 <entry role=
"func_table_entry"><para role=
"func_signature">
24677 <primary>pg_conf_load_time
</primary>
24679 <function>pg_conf_load_time
</function> ()
24680 <returnvalue>timestamp with time zone
</returnvalue>
24683 Returns the time when the server configuration files were last loaded.
24684 If the current session was alive at the time, this will be the time
24685 when the session itself re-read the configuration files (so the
24686 reading will vary a little in different sessions). Otherwise it is
24687 the time when the postmaster process re-read the configuration files.
24692 <entry role=
"func_table_entry"><para role=
"func_signature">
24694 <primary>pg_current_logfile
</primary>
24697 <primary>Logging
</primary>
24698 <secondary>pg_current_logfile function
</secondary>
24701 <primary>current_logfiles
</primary>
24702 <secondary>and the pg_current_logfile function
</secondary>
24705 <primary>Logging
</primary>
24706 <secondary>current_logfiles file and the pg_current_logfile
24707 function
</secondary>
24709 <function>pg_current_logfile
</function> (
<optional> <type>text
</type> </optional> )
24710 <returnvalue>text
</returnvalue>
24713 Returns the path name of the log file currently in use by the logging
24714 collector. The path includes the
<xref linkend=
"guc-log-directory"/>
24715 directory and the individual log file name. The result
24716 is
<literal>NULL
</literal> if the logging collector is disabled.
24717 When multiple log files exist, each in a different
24718 format,
<function>pg_current_logfile
</function> without an argument
24719 returns the path of the file having the first format found in the
24720 ordered list:
<literal>stderr
</literal>,
24721 <literal>csvlog
</literal>,
<literal>jsonlog
</literal>.
24722 <literal>NULL
</literal> is returned if no log file has any of these
24724 To request information about a specific log file format, supply
24725 either
<literal>csvlog
</literal>,
<literal>jsonlog
</literal> or
24726 <literal>stderr
</literal> as the
24727 value of the optional parameter. The result is
<literal>NULL
</literal>
24728 if the log format requested is not configured in
24729 <xref linkend=
"guc-log-destination"/>.
24730 The result reflects the contents of
24731 the
<filename>current_logfiles
</filename> file.
24734 This function is restricted to superusers and roles with privileges of
24735 the
<literal>pg_monitor
</literal> role by default, but other users can
24736 be granted EXECUTE to run the function.
24741 <entry role=
"func_table_entry"><para role=
"func_signature">
24743 <primary>pg_my_temp_schema
</primary>
24745 <function>pg_my_temp_schema
</function> ()
24746 <returnvalue>oid
</returnvalue>
24749 Returns the OID of the current session's temporary schema, or zero if
24750 it has none (because it has not created any temporary tables).
24755 <entry role=
"func_table_entry"><para role=
"func_signature">
24757 <primary>pg_is_other_temp_schema
</primary>
24759 <function>pg_is_other_temp_schema
</function> (
<type>oid
</type> )
24760 <returnvalue>boolean
</returnvalue>
24763 Returns true if the given OID is the OID of another session's
24764 temporary schema. (This can be useful, for example, to exclude other
24765 sessions' temporary tables from a catalog display.)
24770 <entry role=
"func_table_entry"><para role=
"func_signature">
24772 <primary>pg_jit_available
</primary>
24774 <function>pg_jit_available
</function> ()
24775 <returnvalue>boolean
</returnvalue>
24778 Returns true if a
<acronym>JIT
</acronym> compiler extension is
24779 available (see
<xref linkend=
"jit"/>) and the
24780 <xref linkend=
"guc-jit"/> configuration parameter is set to
24781 <literal>on
</literal>.
24786 <entry role=
"func_table_entry"><para role=
"func_signature">
24788 <primary>pg_listening_channels
</primary>
24790 <function>pg_listening_channels
</function> ()
24791 <returnvalue>setof text
</returnvalue>
24794 Returns the set of names of asynchronous notification channels that
24795 the current session is listening to.
24800 <entry role=
"func_table_entry"><para role=
"func_signature">
24802 <primary>pg_notification_queue_usage
</primary>
24804 <function>pg_notification_queue_usage
</function> ()
24805 <returnvalue>double precision
</returnvalue>
24808 Returns the fraction (
0–1) of the asynchronous notification
24809 queue's maximum size that is currently occupied by notifications that
24810 are waiting to be processed.
24811 See
<xref linkend=
"sql-listen"/> and
<xref linkend=
"sql-notify"/>
24812 for more information.
24817 <entry role=
"func_table_entry"><para role=
"func_signature">
24819 <primary>pg_postmaster_start_time
</primary>
24821 <function>pg_postmaster_start_time
</function> ()
24822 <returnvalue>timestamp with time zone
</returnvalue>
24825 Returns the time when the server started.
24830 <entry role=
"func_table_entry"><para role=
"func_signature">
24832 <primary>pg_safe_snapshot_blocking_pids
</primary>
24834 <function>pg_safe_snapshot_blocking_pids
</function> (
<type>integer
</type> )
24835 <returnvalue>integer[]
</returnvalue>
24838 Returns an array of the process ID(s) of the sessions that are blocking
24839 the server process with the specified process ID from acquiring a safe
24840 snapshot, or an empty array if there is no such server process or it
24844 A session running a
<literal>SERIALIZABLE
</literal> transaction blocks
24845 a
<literal>SERIALIZABLE READ ONLY DEFERRABLE
</literal> transaction
24846 from acquiring a snapshot until the latter determines that it is safe
24847 to avoid taking any predicate locks. See
24848 <xref linkend=
"xact-serializable"/> for more information about
24849 serializable and deferrable transactions.
24852 Frequent calls to this function could have some impact on database
24853 performance, because it needs access to the predicate lock manager's
24854 shared state for a short time.
24859 <entry role=
"func_table_entry"><para role=
"func_signature">
24861 <primary>pg_trigger_depth
</primary>
24863 <function>pg_trigger_depth
</function> ()
24864 <returnvalue>integer
</returnvalue>
24867 Returns the current nesting level
24868 of
<productname>PostgreSQL
</productname> triggers (
0 if not called,
24869 directly or indirectly, from inside a trigger).
24874 <entry role=
"func_table_entry"><para role=
"func_signature">
24876 <primary>session_user
</primary>
24878 <function>session_user
</function>
24879 <returnvalue>name
</returnvalue>
24882 Returns the session user's name.
24887 <entry role=
"func_table_entry"><para role=
"func_signature">
24889 <primary>system_user
</primary>
24891 <function>system_user
</function>
24892 <returnvalue>text
</returnvalue>
24895 Returns the authentication method and the identity (if any) that the
24896 user presented during the authentication cycle before they were
24897 assigned a database role. It is represented as
24898 <literal>auth_method:identity
</literal> or
24899 <literal>NULL
</literal> if the user has not been authenticated (for
24900 example if
<link linkend=
"auth-trust">Trust authentication
</link> has
24906 <entry role=
"func_table_entry"><para role=
"func_signature">
24908 <primary>user
</primary>
24910 <function>user
</function>
24911 <returnvalue>name
</returnvalue>
24914 This is equivalent to
<function>current_user
</function>.
24923 <function>current_catalog
</function>,
24924 <function>current_role
</function>,
24925 <function>current_schema
</function>,
24926 <function>current_user
</function>,
24927 <function>session_user
</function>,
24928 and
<function>user
</function> have special syntactic status
24929 in
<acronym>SQL
</acronym>: they must be called without trailing
24930 parentheses. In PostgreSQL, parentheses can optionally be used with
24931 <function>current_schema
</function>, but not with the others.
24936 The
<function>session_user
</function> is normally the user who initiated
24937 the current database connection; but superusers can change this setting
24938 with
<xref linkend=
"sql-set-session-authorization"/>.
24939 The
<function>current_user
</function> is the user identifier
24940 that is applicable for permission checking. Normally it is equal
24941 to the session user, but it can be changed with
24942 <xref linkend=
"sql-set-role"/>.
24943 It also changes during the execution of
24944 functions with the attribute
<literal>SECURITY DEFINER
</literal>.
24945 In Unix parlance, the session user is the
<quote>real user
</quote> and
24946 the current user is the
<quote>effective user
</quote>.
24947 <function>current_role
</function> and
<function>user
</function> are
24948 synonyms for
<function>current_user
</function>. (The SQL standard draws
24949 a distinction between
<function>current_role
</function>
24950 and
<function>current_user
</function>, but
<productname>PostgreSQL
</productname>
24951 does not, since it unifies users and roles into a single kind of entity.)
24956 <sect2 id=
"functions-info-access">
24957 <title>Access Privilege Inquiry Functions
</title>
24960 <primary>privilege
</primary>
24961 <secondary>querying
</secondary>
24965 <xref linkend=
"functions-info-access-table"/> lists functions that
24966 allow querying object access privileges programmatically.
24967 (See
<xref linkend=
"ddl-priv"/> for more information about
24969 In these functions, the user whose privileges are being inquired about
24970 can be specified by name or by OID
24971 (
<structname>pg_authid
</structname>.
<structfield>oid
</structfield>), or if
24972 the name is given as
<literal>public
</literal> then the privileges of the
24973 PUBLIC pseudo-role are checked. Also, the
<parameter>user
</parameter>
24974 argument can be omitted entirely, in which case
24975 the
<function>current_user
</function> is assumed.
24976 The object that is being inquired about can be specified either by name or
24977 by OID, too. When specifying by name, a schema name can be included if
24979 The access privilege of interest is specified by a text string, which must
24980 evaluate to one of the appropriate privilege keywords for the object's type
24981 (e.g.,
<literal>SELECT
</literal>). Optionally,
<literal>WITH GRANT
24982 OPTION
</literal> can be added to a privilege type to test whether the
24983 privilege is held with grant option. Also, multiple privilege types can be
24984 listed separated by commas, in which case the result will be true if any of
24985 the listed privileges is held. (Case of the privilege string is not
24986 significant, and extra whitespace is allowed between but not within
24990 SELECT has_table_privilege('myschema.mytable', 'select');
24991 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
24995 <table id=
"functions-info-access-table">
24996 <title>Access Privilege Inquiry Functions
</title>
25000 <entry role=
"func_table_entry"><para role=
"func_signature">
25011 <entry role=
"func_table_entry"><para role=
"func_signature">
25013 <primary>has_any_column_privilege
</primary>
25015 <function>has_any_column_privilege
</function> (
25016 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25017 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
25018 <parameter>privilege
</parameter> <type>text
</type> )
25019 <returnvalue>boolean
</returnvalue>
25022 Does user have privilege for any column of table?
25023 This succeeds either if the privilege is held for the whole table, or
25024 if there is a column-level grant of the privilege for at least one
25026 Allowable privilege types are
25027 <literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25028 <literal>UPDATE
</literal>, and
<literal>REFERENCES
</literal>.
25033 <entry role=
"func_table_entry"><para role=
"func_signature">
25035 <primary>has_column_privilege
</primary>
25037 <function>has_column_privilege
</function> (
25038 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25039 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
25040 <parameter>column
</parameter> <type>text
</type> or
<type>smallint
</type>,
25041 <parameter>privilege
</parameter> <type>text
</type> )
25042 <returnvalue>boolean
</returnvalue>
25045 Does user have privilege for the specified table column?
25046 This succeeds either if the privilege is held for the whole table, or
25047 if there is a column-level grant of the privilege for the column.
25048 The column can be specified by name or by attribute number
25049 (
<structname>pg_attribute
</structname>.
<structfield>attnum
</structfield>).
25050 Allowable privilege types are
25051 <literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25052 <literal>UPDATE
</literal>, and
<literal>REFERENCES
</literal>.
25057 <entry role=
"func_table_entry"><para role=
"func_signature">
25059 <primary>has_database_privilege
</primary>
25061 <function>has_database_privilege
</function> (
25062 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25063 <parameter>database
</parameter> <type>text
</type> or
<type>oid
</type>,
25064 <parameter>privilege
</parameter> <type>text
</type> )
25065 <returnvalue>boolean
</returnvalue>
25068 Does user have privilege for database?
25069 Allowable privilege types are
25070 <literal>CREATE
</literal>,
25071 <literal>CONNECT
</literal>,
25072 <literal>TEMPORARY
</literal>, and
25073 <literal>TEMP
</literal> (which is equivalent to
25074 <literal>TEMPORARY
</literal>).
25079 <entry role=
"func_table_entry"><para role=
"func_signature">
25081 <primary>has_foreign_data_wrapper_privilege
</primary>
25083 <function>has_foreign_data_wrapper_privilege
</function> (
25084 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25085 <parameter>fdw
</parameter> <type>text
</type> or
<type>oid
</type>,
25086 <parameter>privilege
</parameter> <type>text
</type> )
25087 <returnvalue>boolean
</returnvalue>
25090 Does user have privilege for foreign-data wrapper?
25091 The only allowable privilege type is
<literal>USAGE
</literal>.
25096 <entry role=
"func_table_entry"><para role=
"func_signature">
25098 <primary>has_function_privilege
</primary>
25100 <function>has_function_privilege
</function> (
25101 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25102 <parameter>function
</parameter> <type>text
</type> or
<type>oid
</type>,
25103 <parameter>privilege
</parameter> <type>text
</type> )
25104 <returnvalue>boolean
</returnvalue>
25107 Does user have privilege for function?
25108 The only allowable privilege type is
<literal>EXECUTE
</literal>.
25111 When specifying a function by name rather than by OID, the allowed
25112 input is the same as for the
<type>regprocedure
</type> data type (see
25113 <xref linkend=
"datatype-oid"/>).
25116 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
25122 <entry role=
"func_table_entry"><para role=
"func_signature">
25124 <primary>has_language_privilege
</primary>
25126 <function>has_language_privilege
</function> (
25127 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25128 <parameter>language
</parameter> <type>text
</type> or
<type>oid
</type>,
25129 <parameter>privilege
</parameter> <type>text
</type> )
25130 <returnvalue>boolean
</returnvalue>
25133 Does user have privilege for language?
25134 The only allowable privilege type is
<literal>USAGE
</literal>.
25139 <entry role=
"func_table_entry"><para role=
"func_signature">
25141 <primary>has_largeobject_privilege
</primary>
25143 <function>has_largeobject_privilege
</function> (
25144 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25145 <parameter>largeobject
</parameter> <type>oid
</type>,
25146 <parameter>privilege
</parameter> <type>text
</type> )
25147 <returnvalue>boolean
</returnvalue>
25150 Does user have privilege for large object?
25151 Allowable privilege types are
25152 <literal>SELECT
</literal> and
<literal>UPDATE
</literal>.
25157 <entry role=
"func_table_entry"><para role=
"func_signature">
25159 <primary>has_parameter_privilege
</primary>
25161 <function>has_parameter_privilege
</function> (
25162 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25163 <parameter>parameter
</parameter> <type>text
</type>,
25164 <parameter>privilege
</parameter> <type>text
</type> )
25165 <returnvalue>boolean
</returnvalue>
25168 Does user have privilege for configuration parameter?
25169 The parameter name is case-insensitive.
25170 Allowable privilege types are
<literal>SET
</literal>
25171 and
<literal>ALTER SYSTEM
</literal>.
25176 <entry role=
"func_table_entry"><para role=
"func_signature">
25178 <primary>has_schema_privilege
</primary>
25180 <function>has_schema_privilege
</function> (
25181 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25182 <parameter>schema
</parameter> <type>text
</type> or
<type>oid
</type>,
25183 <parameter>privilege
</parameter> <type>text
</type> )
25184 <returnvalue>boolean
</returnvalue>
25187 Does user have privilege for schema?
25188 Allowable privilege types are
25189 <literal>CREATE
</literal> and
25190 <literal>USAGE
</literal>.
25195 <entry role=
"func_table_entry"><para role=
"func_signature">
25197 <primary>has_sequence_privilege
</primary>
25199 <function>has_sequence_privilege
</function> (
25200 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25201 <parameter>sequence
</parameter> <type>text
</type> or
<type>oid
</type>,
25202 <parameter>privilege
</parameter> <type>text
</type> )
25203 <returnvalue>boolean
</returnvalue>
25206 Does user have privilege for sequence?
25207 Allowable privilege types are
25208 <literal>USAGE
</literal>,
25209 <literal>SELECT
</literal>, and
25210 <literal>UPDATE
</literal>.
25215 <entry role=
"func_table_entry"><para role=
"func_signature">
25217 <primary>has_server_privilege
</primary>
25219 <function>has_server_privilege
</function> (
25220 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25221 <parameter>server
</parameter> <type>text
</type> or
<type>oid
</type>,
25222 <parameter>privilege
</parameter> <type>text
</type> )
25223 <returnvalue>boolean
</returnvalue>
25226 Does user have privilege for foreign server?
25227 The only allowable privilege type is
<literal>USAGE
</literal>.
25232 <entry role=
"func_table_entry"><para role=
"func_signature">
25234 <primary>has_table_privilege
</primary>
25236 <function>has_table_privilege
</function> (
25237 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25238 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
25239 <parameter>privilege
</parameter> <type>text
</type> )
25240 <returnvalue>boolean
</returnvalue>
25243 Does user have privilege for table?
25244 Allowable privilege types
25245 are
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25246 <literal>UPDATE
</literal>,
<literal>DELETE
</literal>,
25247 <literal>TRUNCATE
</literal>,
<literal>REFERENCES
</literal>,
25248 <literal>TRIGGER
</literal>, and
<literal>MAINTAIN
</literal>.
25253 <entry role=
"func_table_entry"><para role=
"func_signature">
25255 <primary>has_tablespace_privilege
</primary>
25257 <function>has_tablespace_privilege
</function> (
25258 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25259 <parameter>tablespace
</parameter> <type>text
</type> or
<type>oid
</type>,
25260 <parameter>privilege
</parameter> <type>text
</type> )
25261 <returnvalue>boolean
</returnvalue>
25264 Does user have privilege for tablespace?
25265 The only allowable privilege type is
<literal>CREATE
</literal>.
25270 <entry role=
"func_table_entry"><para role=
"func_signature">
25272 <primary>has_type_privilege
</primary>
25274 <function>has_type_privilege
</function> (
25275 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25276 <parameter>type
</parameter> <type>text
</type> or
<type>oid
</type>,
25277 <parameter>privilege
</parameter> <type>text
</type> )
25278 <returnvalue>boolean
</returnvalue>
25281 Does user have privilege for data type?
25282 The only allowable privilege type is
<literal>USAGE
</literal>.
25283 When specifying a type by name rather than by OID, the allowed input
25284 is the same as for the
<type>regtype
</type> data type (see
25285 <xref linkend=
"datatype-oid"/>).
25290 <entry role=
"func_table_entry"><para role=
"func_signature">
25292 <primary>pg_has_role
</primary>
25294 <function>pg_has_role
</function> (
25295 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
25296 <parameter>role
</parameter> <type>text
</type> or
<type>oid
</type>,
25297 <parameter>privilege
</parameter> <type>text
</type> )
25298 <returnvalue>boolean
</returnvalue>
25301 Does user have privilege for role?
25302 Allowable privilege types are
25303 <literal>MEMBER
</literal>,
<literal>USAGE
</literal>,
25304 and
<literal>SET
</literal>.
25305 <literal>MEMBER
</literal> denotes direct or indirect membership in
25306 the role without regard to what specific privileges may be conferred.
25307 <literal>USAGE
</literal> denotes whether the privileges of the role
25308 are immediately available without doing
<command>SET ROLE
</command>,
25309 while
<literal>SET
</literal> denotes whether it is possible to change
25310 to the role using the
<literal>SET ROLE
</literal> command.
25311 <literal>WITH ADMIN OPTION
</literal> or
<literal>WITH GRANT
25312 OPTION
</literal> can be added to any of these privilege types to
25313 test whether the
<literal>ADMIN
</literal> privilege is held (all
25314 six spellings test the same thing).
25315 This function does not allow the special case of
25316 setting
<parameter>user
</parameter> to
<literal>public
</literal>,
25317 because the PUBLIC pseudo-role can never be a member of real roles.
25322 <entry role=
"func_table_entry"><para role=
"func_signature">
25324 <primary>row_security_active
</primary>
25326 <function>row_security_active
</function> (
25327 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type> )
25328 <returnvalue>boolean
</returnvalue>
25331 Is row-level security active for the specified table in the context of
25332 the current user and current environment?
25340 <xref linkend=
"functions-aclitem-op-table"/> shows the operators
25341 available for the
<type>aclitem
</type> type, which is the catalog
25342 representation of access privileges. See
<xref linkend=
"ddl-priv"/>
25343 for information about how to read access privilege values.
25346 <table id=
"functions-aclitem-op-table">
25347 <title><type>aclitem
</type> Operators
</title>
25351 <entry role=
"func_table_entry"><para role=
"func_signature">
25365 <entry role=
"func_table_entry"><para role=
"func_signature">
25367 <primary>aclitemeq
</primary>
25369 <type>aclitem
</type> <literal>=
</literal> <type>aclitem
</type>
25370 <returnvalue>boolean
</returnvalue>
25373 Are
<type>aclitem
</type>s equal? (Notice that
25374 type
<type>aclitem
</type> lacks the usual set of comparison
25375 operators; it has only equality. In turn,
<type>aclitem
</type>
25376 arrays can only be compared for equality.)
25379 <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem
</literal>
25380 <returnvalue>f
</returnvalue>
25385 <entry role=
"func_table_entry"><para role=
"func_signature">
25387 <primary>aclcontains
</primary>
25389 <type>aclitem[]
</type> <literal>@
></literal> <type>aclitem
</type>
25390 <returnvalue>boolean
</returnvalue>
25393 Does array contain the specified privileges? (This is true if there
25394 is an array entry that matches the
<type>aclitem
</type>'s grantee and
25395 grantor, and has at least the specified set of privileges.)
25398 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @
> 'calvin=r*/hobbes'::aclitem
</literal>
25399 <returnvalue>t
</returnvalue>
25404 <entry role=
"func_table_entry"><para role=
"func_signature">
25405 <type>aclitem[]
</type> <literal>~
</literal> <type>aclitem
</type>
25406 <returnvalue>boolean
</returnvalue>
25409 This is a deprecated alias for
<literal>@
></literal>.
25412 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem
</literal>
25413 <returnvalue>t
</returnvalue>
25421 <xref linkend=
"functions-aclitem-fn-table"/> shows some additional
25422 functions to manage the
<type>aclitem
</type> type.
25425 <table id=
"functions-aclitem-fn-table">
25426 <title><type>aclitem
</type> Functions
</title>
25430 <entry role=
"func_table_entry"><para role=
"func_signature">
25441 <entry role=
"func_table_entry"><para role=
"func_signature">
25443 <primary>acldefault
</primary>
25445 <function>acldefault
</function> (
25446 <parameter>type
</parameter> <type>"char"</type>,
25447 <parameter>ownerId
</parameter> <type>oid
</type> )
25448 <returnvalue>aclitem[]
</returnvalue>
25451 Constructs an
<type>aclitem
</type> array holding the default access
25452 privileges for an object of type
<parameter>type
</parameter> belonging
25453 to the role with OID
<parameter>ownerId
</parameter>. This represents
25454 the access privileges that will be assumed when an object's
25455 <acronym>ACL
</acronym> entry is null. (The default access privileges
25456 are described in
<xref linkend=
"ddl-priv"/>.)
25457 The
<parameter>type
</parameter> parameter must be one of
25458 'c' for
<literal>COLUMN
</literal>,
25459 'r' for
<literal>TABLE
</literal> and table-like objects,
25460 's' for
<literal>SEQUENCE
</literal>,
25461 'd' for
<literal>DATABASE
</literal>,
25462 'f' for
<literal>FUNCTION
</literal> or
<literal>PROCEDURE
</literal>,
25463 'l' for
<literal>LANGUAGE
</literal>,
25464 'L' for
<literal>LARGE OBJECT
</literal>,
25465 'n' for
<literal>SCHEMA
</literal>,
25466 'p' for
<literal>PARAMETER
</literal>,
25467 't' for
<literal>TABLESPACE
</literal>,
25468 'F' for
<literal>FOREIGN DATA WRAPPER
</literal>,
25469 'S' for
<literal>FOREIGN SERVER
</literal>,
25471 'T' for
<literal>TYPE
</literal> or
<literal>DOMAIN
</literal>.
25476 <entry role=
"func_table_entry"><para role=
"func_signature">
25478 <primary>aclexplode
</primary>
25480 <function>aclexplode
</function> (
<type>aclitem[]
</type> )
25481 <returnvalue>setof record
</returnvalue>
25482 (
<parameter>grantor
</parameter> <type>oid
</type>,
25483 <parameter>grantee
</parameter> <type>oid
</type>,
25484 <parameter>privilege_type
</parameter> <type>text
</type>,
25485 <parameter>is_grantable
</parameter> <type>boolean
</type> )
25488 Returns the
<type>aclitem
</type> array as a set of rows.
25489 If the grantee is the pseudo-role PUBLIC, it is represented by zero in
25490 the
<parameter>grantee
</parameter> column. Each granted privilege is
25491 represented as
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
25492 etc (see
<xref linkend=
"privilege-abbrevs-table"/> for a full list).
25493 Note that each privilege is broken out as a separate row, so
25494 only one keyword appears in the
<parameter>privilege_type
</parameter>
25500 <entry role=
"func_table_entry"><para role=
"func_signature">
25502 <primary>makeaclitem
</primary>
25504 <function>makeaclitem
</function> (
25505 <parameter>grantee
</parameter> <type>oid
</type>,
25506 <parameter>grantor
</parameter> <type>oid
</type>,
25507 <parameter>privileges
</parameter> <type>text
</type>,
25508 <parameter>is_grantable
</parameter> <type>boolean
</type> )
25509 <returnvalue>aclitem
</returnvalue>
25512 Constructs an
<type>aclitem
</type> with the given properties.
25513 <parameter>privileges
</parameter> is a comma-separated list of
25514 privilege names such as
<literal>SELECT
</literal>,
25515 <literal>INSERT
</literal>, etc, all of which are set in the
25516 result. (Case of the privilege string is not significant, and
25517 extra whitespace is allowed between but not within privilege
25527 <sect2 id=
"functions-info-schema">
25528 <title>Schema Visibility Inquiry Functions
</title>
25531 <xref linkend=
"functions-info-schema-table"/> shows functions that
25532 determine whether a certain object is
<firstterm>visible
</firstterm> in the
25533 current schema search path.
25534 For example, a table is said to be visible if its
25535 containing schema is in the search path and no table of the same
25536 name appears earlier in the search path. This is equivalent to the
25537 statement that the table can be referenced by name without explicit
25538 schema qualification. Thus, to list the names of all visible tables:
25540 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
25542 For functions and operators, an object in the search path is said to be
25543 visible if there is no object of the same name
<emphasis>and argument data
25544 type(s)
</emphasis> earlier in the path. For operator classes and families,
25545 both the name and the associated index access method are considered.
25549 <primary>search path
</primary>
25550 <secondary>object visibility
</secondary>
25553 <table id=
"functions-info-schema-table">
25554 <title>Schema Visibility Inquiry Functions
</title>
25558 <entry role=
"func_table_entry"><para role=
"func_signature">
25569 <entry role=
"func_table_entry"><para role=
"func_signature">
25571 <primary>pg_collation_is_visible
</primary>
25573 <function>pg_collation_is_visible
</function> (
<parameter>collation
</parameter> <type>oid
</type> )
25574 <returnvalue>boolean
</returnvalue>
25577 Is collation visible in search path?
25582 <entry role=
"func_table_entry"><para role=
"func_signature">
25584 <primary>pg_conversion_is_visible
</primary>
25586 <function>pg_conversion_is_visible
</function> (
<parameter>conversion
</parameter> <type>oid
</type> )
25587 <returnvalue>boolean
</returnvalue>
25590 Is conversion visible in search path?
25595 <entry role=
"func_table_entry"><para role=
"func_signature">
25597 <primary>pg_function_is_visible
</primary>
25599 <function>pg_function_is_visible
</function> (
<parameter>function
</parameter> <type>oid
</type> )
25600 <returnvalue>boolean
</returnvalue>
25603 Is function visible in search path?
25604 (This also works for procedures and aggregates.)
25609 <entry role=
"func_table_entry"><para role=
"func_signature">
25611 <primary>pg_opclass_is_visible
</primary>
25613 <function>pg_opclass_is_visible
</function> (
<parameter>opclass
</parameter> <type>oid
</type> )
25614 <returnvalue>boolean
</returnvalue>
25617 Is operator class visible in search path?
25622 <entry role=
"func_table_entry"><para role=
"func_signature">
25624 <primary>pg_operator_is_visible
</primary>
25626 <function>pg_operator_is_visible
</function> (
<parameter>operator
</parameter> <type>oid
</type> )
25627 <returnvalue>boolean
</returnvalue>
25630 Is operator visible in search path?
25635 <entry role=
"func_table_entry"><para role=
"func_signature">
25637 <primary>pg_opfamily_is_visible
</primary>
25639 <function>pg_opfamily_is_visible
</function> (
<parameter>opclass
</parameter> <type>oid
</type> )
25640 <returnvalue>boolean
</returnvalue>
25643 Is operator family visible in search path?
25648 <entry role=
"func_table_entry"><para role=
"func_signature">
25650 <primary>pg_statistics_obj_is_visible
</primary>
25652 <function>pg_statistics_obj_is_visible
</function> (
<parameter>stat
</parameter> <type>oid
</type> )
25653 <returnvalue>boolean
</returnvalue>
25656 Is statistics object visible in search path?
25661 <entry role=
"func_table_entry"><para role=
"func_signature">
25663 <primary>pg_table_is_visible
</primary>
25665 <function>pg_table_is_visible
</function> (
<parameter>table
</parameter> <type>oid
</type> )
25666 <returnvalue>boolean
</returnvalue>
25669 Is table visible in search path?
25670 (This works for all types of relations, including views, materialized
25671 views, indexes, sequences and foreign tables.)
25676 <entry role=
"func_table_entry"><para role=
"func_signature">
25678 <primary>pg_ts_config_is_visible
</primary>
25680 <function>pg_ts_config_is_visible
</function> (
<parameter>config
</parameter> <type>oid
</type> )
25681 <returnvalue>boolean
</returnvalue>
25684 Is text search configuration visible in search path?
25689 <entry role=
"func_table_entry"><para role=
"func_signature">
25691 <primary>pg_ts_dict_is_visible
</primary>
25693 <function>pg_ts_dict_is_visible
</function> (
<parameter>dict
</parameter> <type>oid
</type> )
25694 <returnvalue>boolean
</returnvalue>
25697 Is text search dictionary visible in search path?
25702 <entry role=
"func_table_entry"><para role=
"func_signature">
25704 <primary>pg_ts_parser_is_visible
</primary>
25706 <function>pg_ts_parser_is_visible
</function> (
<parameter>parser
</parameter> <type>oid
</type> )
25707 <returnvalue>boolean
</returnvalue>
25710 Is text search parser visible in search path?
25715 <entry role=
"func_table_entry"><para role=
"func_signature">
25717 <primary>pg_ts_template_is_visible
</primary>
25719 <function>pg_ts_template_is_visible
</function> (
<parameter>template
</parameter> <type>oid
</type> )
25720 <returnvalue>boolean
</returnvalue>
25723 Is text search template visible in search path?
25728 <entry role=
"func_table_entry"><para role=
"func_signature">
25730 <primary>pg_type_is_visible
</primary>
25732 <function>pg_type_is_visible
</function> (
<parameter>type
</parameter> <type>oid
</type> )
25733 <returnvalue>boolean
</returnvalue>
25736 Is type (or domain) visible in search path?
25744 All these functions require object OIDs to identify the object to be
25745 checked. If you want to test an object by name, it is convenient to use
25746 the OID alias types (
<type>regclass
</type>,
<type>regtype
</type>,
25747 <type>regprocedure
</type>,
<type>regoperator
</type>,
<type>regconfig
</type>,
25748 or
<type>regdictionary
</type>),
25751 SELECT pg_type_is_visible('myschema.widget'::regtype);
25753 Note that it would not make much sense to test a non-schema-qualified
25754 type name in this way
— if the name can be recognized at all, it must be visible.
25759 <sect2 id=
"functions-info-catalog">
25760 <title>System Catalog Information Functions
</title>
25763 <xref linkend=
"functions-info-catalog-table"/> lists functions that
25764 extract information from the system catalogs.
25767 <table id=
"functions-info-catalog-table">
25768 <title>System Catalog Information Functions
</title>
25772 <entry role=
"func_table_entry"><para role=
"func_signature">
25783 <entry id=
"format-type" xreflabel=
"format_type" role=
"func_table_entry"><para role=
"func_signature">
25785 <primary>format_type
</primary>
25787 <function>format_type
</function> (
<parameter>type
</parameter> <type>oid
</type>,
<parameter>typemod
</parameter> <type>integer
</type> )
25788 <returnvalue>text
</returnvalue>
25791 Returns the SQL name for a data type that is identified by its type
25792 OID and possibly a type modifier. Pass NULL for the type modifier if
25793 no specific modifier is known.
25798 <entry role=
"func_table_entry"><para role=
"func_signature">
25800 <primary>pg_basetype
</primary>
25802 <function>pg_basetype
</function> (
<type>regtype
</type> )
25803 <returnvalue>regtype
</returnvalue>
25806 Returns the OID of the base type of a domain identified by its
25807 type OID. If the argument is the OID of a non-domain type,
25808 returns the argument as-is. Returns NULL if the argument is
25809 not a valid type OID. If there's a chain of domain dependencies,
25810 it will recurse until finding the base type.
25813 Assuming
<literal>CREATE DOMAIN mytext AS text
</literal>:
25816 <literal>pg_basetype('mytext'::regtype)
</literal>
25817 <returnvalue>text
</returnvalue>
25822 <entry id=
"pg-char-to-encoding" role=
"func_table_entry"><para role=
"func_signature">
25824 <primary>pg_char_to_encoding
</primary>
25826 <function>pg_char_to_encoding
</function> (
<parameter>encoding
</parameter> <type>name
</type> )
25827 <returnvalue>integer
</returnvalue>
25830 Converts the supplied encoding name into an integer representing the
25831 internal identifier used in some system catalog tables.
25832 Returns
<literal>-
1</literal> if an unknown encoding name is provided.
25837 <entry id=
"pg-encoding-to-char" role=
"func_table_entry"><para role=
"func_signature">
25839 <primary>pg_encoding_to_char
</primary>
25841 <function>pg_encoding_to_char
</function> (
<parameter>encoding
</parameter> <type>integer
</type> )
25842 <returnvalue>name
</returnvalue>
25845 Converts the integer used as the internal identifier of an encoding in some
25846 system catalog tables into a human-readable string.
25847 Returns an empty string if an invalid encoding number is provided.
25852 <entry role=
"func_table_entry"><para role=
"func_signature">
25854 <primary>pg_get_catalog_foreign_keys
</primary>
25856 <function>pg_get_catalog_foreign_keys
</function> ()
25857 <returnvalue>setof record
</returnvalue>
25858 (
<parameter>fktable
</parameter> <type>regclass
</type>,
25859 <parameter>fkcols
</parameter> <type>text[]
</type>,
25860 <parameter>pktable
</parameter> <type>regclass
</type>,
25861 <parameter>pkcols
</parameter> <type>text[]
</type>,
25862 <parameter>is_array
</parameter> <type>boolean
</type>,
25863 <parameter>is_opt
</parameter> <type>boolean
</type> )
25866 Returns a set of records describing the foreign key relationships
25867 that exist within the
<productname>PostgreSQL
</productname> system
25869 The
<parameter>fktable
</parameter> column contains the name of the
25870 referencing catalog, and the
<parameter>fkcols
</parameter> column
25871 contains the name(s) of the referencing column(s). Similarly,
25872 the
<parameter>pktable
</parameter> column contains the name of the
25873 referenced catalog, and the
<parameter>pkcols
</parameter> column
25874 contains the name(s) of the referenced column(s).
25875 If
<parameter>is_array
</parameter> is true, the last referencing
25876 column is an array, each of whose elements should match some entry
25877 in the referenced catalog.
25878 If
<parameter>is_opt
</parameter> is true, the referencing column(s)
25879 are allowed to contain zeroes instead of a valid reference.
25884 <entry role=
"func_table_entry"><para role=
"func_signature">
25886 <primary>pg_get_constraintdef
</primary>
25888 <function>pg_get_constraintdef
</function> (
<parameter>constraint
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
25889 <returnvalue>text
</returnvalue>
25892 Reconstructs the creating command for a constraint.
25893 (This is a decompiled reconstruction, not the original text
25899 <entry role=
"func_table_entry"><para role=
"func_signature">
25901 <primary>pg_get_expr
</primary>
25903 <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> )
25904 <returnvalue>text
</returnvalue>
25907 Decompiles the internal form of an expression stored in the system
25908 catalogs, such as the default value for a column. If the expression
25909 might contain Vars, specify the OID of the relation they refer to as
25910 the second parameter; if no Vars are expected, passing zero is
25916 <entry role=
"func_table_entry"><para role=
"func_signature">
25918 <primary>pg_get_functiondef
</primary>
25920 <function>pg_get_functiondef
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25921 <returnvalue>text
</returnvalue>
25924 Reconstructs the creating command for a function or procedure.
25925 (This is a decompiled reconstruction, not the original text
25927 The result is a complete
<command>CREATE OR REPLACE FUNCTION
</command>
25928 or
<command>CREATE OR REPLACE PROCEDURE
</command> statement.
25933 <entry role=
"func_table_entry"><para role=
"func_signature">
25935 <primary>pg_get_function_arguments
</primary>
25937 <function>pg_get_function_arguments
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25938 <returnvalue>text
</returnvalue>
25941 Reconstructs the argument list of a function or procedure, in the form
25942 it would need to appear in within
<command>CREATE FUNCTION
</command>
25943 (including default values).
25948 <entry role=
"func_table_entry"><para role=
"func_signature">
25950 <primary>pg_get_function_identity_arguments
</primary>
25952 <function>pg_get_function_identity_arguments
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25953 <returnvalue>text
</returnvalue>
25956 Reconstructs the argument list necessary to identify a function or
25957 procedure, in the form it would need to appear in within commands such
25958 as
<command>ALTER FUNCTION
</command>. This form omits default values.
25963 <entry role=
"func_table_entry"><para role=
"func_signature">
25965 <primary>pg_get_function_result
</primary>
25967 <function>pg_get_function_result
</function> (
<parameter>func
</parameter> <type>oid
</type> )
25968 <returnvalue>text
</returnvalue>
25971 Reconstructs the
<literal>RETURNS
</literal> clause of a function, in
25972 the form it would need to appear in within
<command>CREATE
25973 FUNCTION
</command>. Returns
<literal>NULL
</literal> for a procedure.
25978 <entry role=
"func_table_entry"><para role=
"func_signature">
25980 <primary>pg_get_indexdef
</primary>
25982 <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> )
25983 <returnvalue>text
</returnvalue>
25986 Reconstructs the creating command for an index.
25987 (This is a decompiled reconstruction, not the original text
25988 of the command.) If
<parameter>column
</parameter> is supplied and is
25989 not zero, only the definition of that column is reconstructed.
25994 <entry role=
"func_table_entry"><para role=
"func_signature">
25996 <primary>pg_get_keywords
</primary>
25998 <function>pg_get_keywords
</function> ()
25999 <returnvalue>setof record
</returnvalue>
26000 (
<parameter>word
</parameter> <type>text
</type>,
26001 <parameter>catcode
</parameter> <type>"char"</type>,
26002 <parameter>barelabel
</parameter> <type>boolean
</type>,
26003 <parameter>catdesc
</parameter> <type>text
</type>,
26004 <parameter>baredesc
</parameter> <type>text
</type> )
26007 Returns a set of records describing the SQL keywords recognized by the
26008 server. The
<parameter>word
</parameter> column contains the
26009 keyword. The
<parameter>catcode
</parameter> column contains a
26010 category code:
<literal>U
</literal> for an unreserved
26011 keyword,
<literal>C
</literal> for a keyword that can be a column
26012 name,
<literal>T
</literal> for a keyword that can be a type or
26013 function name, or
<literal>R
</literal> for a fully reserved keyword.
26014 The
<parameter>barelabel
</parameter> column
26015 contains
<literal>true
</literal> if the keyword can be used as
26016 a
<quote>bare
</quote> column label in
<command>SELECT
</command> lists,
26017 or
<literal>false
</literal> if it can only be used
26018 after
<literal>AS
</literal>.
26019 The
<parameter>catdesc
</parameter> column contains a
26020 possibly-localized string describing the keyword's category.
26021 The
<parameter>baredesc
</parameter> column contains a
26022 possibly-localized string describing the keyword's column label status.
26027 <entry role=
"func_table_entry"><para role=
"func_signature">
26029 <primary>pg_get_partkeydef
</primary>
26031 <function>pg_get_partkeydef
</function> (
<parameter>table
</parameter> <type>oid
</type> )
26032 <returnvalue>text
</returnvalue>
26035 Reconstructs the definition of a partitioned table's partition
26036 key, in the form it would have in the
<literal>PARTITION
26037 BY
</literal> clause of
<command>CREATE TABLE
</command>.
26038 (This is a decompiled reconstruction, not the original text
26044 <entry role=
"func_table_entry"><para role=
"func_signature">
26046 <primary>pg_get_ruledef
</primary>
26048 <function>pg_get_ruledef
</function> (
<parameter>rule
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26049 <returnvalue>text
</returnvalue>
26052 Reconstructs the creating command for a rule.
26053 (This is a decompiled reconstruction, not the original text
26059 <entry role=
"func_table_entry"><para role=
"func_signature">
26061 <primary>pg_get_serial_sequence
</primary>
26063 <function>pg_get_serial_sequence
</function> (
<parameter>table
</parameter> <type>text
</type>,
<parameter>column
</parameter> <type>text
</type> )
26064 <returnvalue>text
</returnvalue>
26067 Returns the name of the sequence associated with a column,
26068 or NULL if no sequence is associated with the column.
26069 If the column is an identity column, the associated sequence is the
26070 sequence internally created for that column.
26071 For columns created using one of the serial types
26072 (
<type>serial
</type>,
<type>smallserial
</type>,
<type>bigserial
</type>),
26073 it is the sequence created for that serial column definition.
26074 In the latter case, the association can be modified or removed
26075 with
<command>ALTER SEQUENCE OWNED BY
</command>.
26076 (This function probably should have been
26077 called
<function>pg_get_owned_sequence
</function>; its current name
26078 reflects the fact that it has historically been used with serial-type
26079 columns.) The first parameter is a table name with optional
26080 schema, and the second parameter is a column name. Because the first
26081 parameter potentially contains both schema and table names, it is
26082 parsed per usual SQL rules, meaning it is lower-cased by default.
26083 The second parameter, being just a column name, is treated literally
26084 and so has its case preserved. The result is suitably formatted
26085 for passing to the sequence functions (see
26086 <xref linkend=
"functions-sequence"/>).
26089 A typical use is in reading the current value of the sequence for an
26090 identity or serial column, for example:
26092 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
26098 <entry role=
"func_table_entry"><para role=
"func_signature">
26100 <primary>pg_get_statisticsobjdef
</primary>
26102 <function>pg_get_statisticsobjdef
</function> (
<parameter>statobj
</parameter> <type>oid
</type> )
26103 <returnvalue>text
</returnvalue>
26106 Reconstructs the creating command for an extended statistics object.
26107 (This is a decompiled reconstruction, not the original text
26113 <entry role=
"func_table_entry"><para role=
"func_signature">
26115 <primary>pg_get_triggerdef
</primary>
26117 <function>pg_get_triggerdef
</function> (
<parameter>trigger
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26118 <returnvalue>text
</returnvalue>
26121 Reconstructs the creating command for a trigger.
26122 (This is a decompiled reconstruction, not the original text
26128 <entry role=
"func_table_entry"><para role=
"func_signature">
26130 <primary>pg_get_userbyid
</primary>
26132 <function>pg_get_userbyid
</function> (
<parameter>role
</parameter> <type>oid
</type> )
26133 <returnvalue>name
</returnvalue>
26136 Returns a role's name given its OID.
26141 <entry role=
"func_table_entry"><para role=
"func_signature">
26143 <primary>pg_get_viewdef
</primary>
26145 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26146 <returnvalue>text
</returnvalue>
26149 Reconstructs the underlying
<command>SELECT
</command> command for a
26150 view or materialized view. (This is a decompiled reconstruction, not
26151 the original text of the command.)
26156 <entry role=
"func_table_entry"><para role=
"func_signature">
26157 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>oid
</type>,
<parameter>wrap_column
</parameter> <type>integer
</type> )
26158 <returnvalue>text
</returnvalue>
26161 Reconstructs the underlying
<command>SELECT
</command> command for a
26162 view or materialized view. (This is a decompiled reconstruction, not
26163 the original text of the command.) In this form of the function,
26164 pretty-printing is always enabled, and long lines are wrapped to try
26165 to keep them shorter than the specified number of columns.
26170 <entry role=
"func_table_entry"><para role=
"func_signature">
26171 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>text
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
26172 <returnvalue>text
</returnvalue>
26175 Reconstructs the underlying
<command>SELECT
</command> command for a
26176 view or materialized view, working from a textual name for the view
26177 rather than its OID. (This is deprecated; use the OID variant
26183 <entry role=
"func_table_entry"><para role=
"func_signature">
26185 <primary>pg_index_column_has_property
</primary>
26187 <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> )
26188 <returnvalue>boolean
</returnvalue>
26191 Tests whether an index column has the named property.
26192 Common index column properties are listed in
26193 <xref linkend=
"functions-info-index-column-props"/>.
26194 (Note that extension access methods can define additional property
26195 names for their indexes.)
26196 <literal>NULL
</literal> is returned if the property name is not known
26197 or does not apply to the particular object, or if the OID or column
26198 number does not identify a valid object.
26203 <entry role=
"func_table_entry"><para role=
"func_signature">
26205 <primary>pg_index_has_property
</primary>
26207 <function>pg_index_has_property
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>property
</parameter> <type>text
</type> )
26208 <returnvalue>boolean
</returnvalue>
26211 Tests whether an index has the named property.
26212 Common index properties are listed in
26213 <xref linkend=
"functions-info-index-props"/>.
26214 (Note that extension access methods can define additional property
26215 names for their indexes.)
26216 <literal>NULL
</literal> is returned if the property name is not known
26217 or does not apply to the particular object, or if the OID does not
26218 identify a valid object.
26223 <entry role=
"func_table_entry"><para role=
"func_signature">
26225 <primary>pg_indexam_has_property
</primary>
26227 <function>pg_indexam_has_property
</function> (
<parameter>am
</parameter> <type>oid
</type>,
<parameter>property
</parameter> <type>text
</type> )
26228 <returnvalue>boolean
</returnvalue>
26231 Tests whether an index access method has the named property.
26232 Access method properties are listed in
26233 <xref linkend=
"functions-info-indexam-props"/>.
26234 <literal>NULL
</literal> is returned if the property name is not known
26235 or does not apply to the particular object, or if the OID does not
26236 identify a valid object.
26241 <entry role=
"func_table_entry"><para role=
"func_signature">
26243 <primary>pg_options_to_table
</primary>
26245 <function>pg_options_to_table
</function> (
<parameter>options_array
</parameter> <type>text[]
</type> )
26246 <returnvalue>setof record
</returnvalue>
26247 (
<parameter>option_name
</parameter> <type>text
</type>,
26248 <parameter>option_value
</parameter> <type>text
</type> )
26251 Returns the set of storage options represented by a value from
26252 <structname>pg_class
</structname>.
<structfield>reloptions
</structfield> or
26253 <structname>pg_attribute
</structname>.
<structfield>attoptions
</structfield>.
26258 <entry role=
"func_table_entry"><para role=
"func_signature">
26260 <primary>pg_settings_get_flags
</primary>
26262 <function>pg_settings_get_flags
</function> (
<parameter>guc
</parameter> <type>text
</type> )
26263 <returnvalue>text[]
</returnvalue>
26266 Returns an array of the flags associated with the given GUC, or
26267 <literal>NULL
</literal> if it does not exist. The result is
26268 an empty array if the GUC exists but there are no flags to show.
26269 Only the most useful flags listed in
26270 <xref linkend=
"functions-pg-settings-flags"/> are exposed.
26275 <entry role=
"func_table_entry"><para role=
"func_signature">
26277 <primary>pg_tablespace_databases
</primary>
26279 <function>pg_tablespace_databases
</function> (
<parameter>tablespace
</parameter> <type>oid
</type> )
26280 <returnvalue>setof oid
</returnvalue>
26283 Returns the set of OIDs of databases that have objects stored in the
26284 specified tablespace. If this function returns any rows, the
26285 tablespace is not empty and cannot be dropped. To identify the specific
26286 objects populating the tablespace, you will need to connect to the
26287 database(s) identified by
<function>pg_tablespace_databases
</function>
26288 and query their
<structname>pg_class
</structname> catalogs.
26293 <entry role=
"func_table_entry"><para role=
"func_signature">
26295 <primary>pg_tablespace_location
</primary>
26297 <function>pg_tablespace_location
</function> (
<parameter>tablespace
</parameter> <type>oid
</type> )
26298 <returnvalue>text
</returnvalue>
26301 Returns the file system path that this tablespace is located in.
26306 <entry role=
"func_table_entry"><para role=
"func_signature">
26308 <primary>pg_typeof
</primary>
26310 <function>pg_typeof
</function> (
<type>"any"</type> )
26311 <returnvalue>regtype
</returnvalue>
26314 Returns the OID of the data type of the value that is passed to it.
26315 This can be helpful for troubleshooting or dynamically constructing
26316 SQL queries. The function is declared as
26317 returning
<type>regtype
</type>, which is an OID alias type (see
26318 <xref linkend=
"datatype-oid"/>); this means that it is the same as an
26319 OID for comparison purposes but displays as a type name.
26322 <literal>pg_typeof(
33)
</literal>
26323 <returnvalue>integer
</returnvalue>
26328 <entry role=
"func_table_entry"><para role=
"func_signature">
26330 <primary>COLLATION FOR
</primary>
26332 <function>COLLATION FOR
</function> (
<type>"any"</type> )
26333 <returnvalue>text
</returnvalue>
26336 Returns the name of the collation of the value that is passed to it.
26337 The value is quoted and schema-qualified if necessary. If no
26338 collation was derived for the argument expression,
26339 then
<literal>NULL
</literal> is returned. If the argument is not of a
26340 collatable data type, then an error is raised.
26343 <literal>collation for ('foo'::text)
</literal>
26344 <returnvalue>"default"</returnvalue>
26347 <literal>collation for ('foo' COLLATE
"de_DE")
</literal>
26348 <returnvalue>"de_DE"</returnvalue>
26353 <entry role=
"func_table_entry"><para role=
"func_signature">
26355 <primary>to_regclass
</primary>
26357 <function>to_regclass
</function> (
<type>text
</type> )
26358 <returnvalue>regclass
</returnvalue>
26361 Translates a textual relation name to its OID. A similar result is
26362 obtained by casting the string to type
<type>regclass
</type> (see
26363 <xref linkend=
"datatype-oid"/>); however, this function will return
26364 <literal>NULL
</literal> rather than throwing an error if the name is
26370 <entry role=
"func_table_entry"><para role=
"func_signature">
26372 <primary>to_regcollation
</primary>
26374 <function>to_regcollation
</function> (
<type>text
</type> )
26375 <returnvalue>regcollation
</returnvalue>
26378 Translates a textual collation name to its OID. A similar result is
26379 obtained by casting the string to type
<type>regcollation
</type> (see
26380 <xref linkend=
"datatype-oid"/>); however, this function will return
26381 <literal>NULL
</literal> rather than throwing an error if the name is
26387 <entry role=
"func_table_entry"><para role=
"func_signature">
26389 <primary>to_regnamespace
</primary>
26391 <function>to_regnamespace
</function> (
<type>text
</type> )
26392 <returnvalue>regnamespace
</returnvalue>
26395 Translates a textual schema name to its OID. A similar result is
26396 obtained by casting the string to type
<type>regnamespace
</type> (see
26397 <xref linkend=
"datatype-oid"/>); however, this function will return
26398 <literal>NULL
</literal> rather than throwing an error if the name is
26404 <entry role=
"func_table_entry"><para role=
"func_signature">
26406 <primary>to_regoper
</primary>
26408 <function>to_regoper
</function> (
<type>text
</type> )
26409 <returnvalue>regoper
</returnvalue>
26412 Translates a textual operator name to its OID. A similar result is
26413 obtained by casting the string to type
<type>regoper
</type> (see
26414 <xref linkend=
"datatype-oid"/>); however, this function will return
26415 <literal>NULL
</literal> rather than throwing an error if the name is
26416 not found or is ambiguous.
26421 <entry role=
"func_table_entry"><para role=
"func_signature">
26423 <primary>to_regoperator
</primary>
26425 <function>to_regoperator
</function> (
<type>text
</type> )
26426 <returnvalue>regoperator
</returnvalue>
26429 Translates a textual operator name (with parameter types) to its OID. A similar result is
26430 obtained by casting the string to type
<type>regoperator
</type> (see
26431 <xref linkend=
"datatype-oid"/>); however, this function will return
26432 <literal>NULL
</literal> rather than throwing an error if the name is
26438 <entry role=
"func_table_entry"><para role=
"func_signature">
26440 <primary>to_regproc
</primary>
26442 <function>to_regproc
</function> (
<type>text
</type> )
26443 <returnvalue>regproc
</returnvalue>
26446 Translates a textual function or procedure name to its OID. A similar result is
26447 obtained by casting the string to type
<type>regproc
</type> (see
26448 <xref linkend=
"datatype-oid"/>); however, this function will return
26449 <literal>NULL
</literal> rather than throwing an error if the name is
26450 not found or is ambiguous.
26455 <entry role=
"func_table_entry"><para role=
"func_signature">
26457 <primary>to_regprocedure
</primary>
26459 <function>to_regprocedure
</function> (
<type>text
</type> )
26460 <returnvalue>regprocedure
</returnvalue>
26463 Translates a textual function or procedure name (with argument types) to its OID. A similar result is
26464 obtained by casting the string to type
<type>regprocedure
</type> (see
26465 <xref linkend=
"datatype-oid"/>); however, this function will return
26466 <literal>NULL
</literal> rather than throwing an error if the name is
26472 <entry role=
"func_table_entry"><para role=
"func_signature">
26474 <primary>to_regrole
</primary>
26476 <function>to_regrole
</function> (
<type>text
</type> )
26477 <returnvalue>regrole
</returnvalue>
26480 Translates a textual role name to its OID. A similar result is
26481 obtained by casting the string to type
<type>regrole
</type> (see
26482 <xref linkend=
"datatype-oid"/>); however, this function will return
26483 <literal>NULL
</literal> rather than throwing an error if the name is
26489 <entry id=
"to-regtype" xreflabel=
"to_regtype" role=
"func_table_entry"><para role=
"func_signature">
26491 <primary>to_regtype
</primary>
26493 <function>to_regtype
</function> (
<type>text
</type> )
26494 <returnvalue>regtype
</returnvalue>
26497 Parses a string of text, extracts a potential type name from it,
26498 and translates that name into a type OID. A syntax error in the
26499 string will result in an error; but if the string is a
26500 syntactically valid type name that happens not to be found in the
26501 catalogs, the result is
<literal>NULL
</literal>. A similar result
26502 is obtained by casting the string to type
<type>regtype
</type>
26503 (see
<xref linkend=
"datatype-oid"/>), except that that will throw
26504 error for name not found.
26509 <entry role=
"func_table_entry"><para role=
"func_signature">
26511 <primary>to_regtypemod
</primary>
26513 <function>to_regtypemod
</function> (
<type>text
</type> )
26514 <returnvalue>integer
</returnvalue>
26517 Parses a string of text, extracts a potential type name from it,
26518 and translates its type modifier, if any. A syntax error in the
26519 string will result in an error; but if the string is a
26520 syntactically valid type name that happens not to be found in the
26521 catalogs, the result is
<literal>NULL
</literal>. The result is
26522 <literal>-
1</literal> if no type modifier is present.
26525 <function>to_regtypemod
</function> can be combined with
26526 <xref linkend=
"to-regtype"/> to produce appropriate inputs for
26527 <xref linkend=
"format-type"/>, allowing a string representing a
26528 type name to be canonicalized.
26531 <literal>format_type(to_regtype('varchar(
32)'), to_regtypemod('varchar(
32)'))
</literal>
26532 <returnvalue>character varying(
32)
</returnvalue>
26540 Most of the functions that reconstruct (decompile) database objects
26541 have an optional
<parameter>pretty
</parameter> flag, which
26542 if
<literal>true
</literal> causes the result to
26543 be
<quote>pretty-printed
</quote>. Pretty-printing suppresses unnecessary
26544 parentheses and adds whitespace for legibility.
26545 The pretty-printed format is more readable, but the default format
26546 is more likely to be interpreted the same way by future versions of
26547 <productname>PostgreSQL
</productname>; so avoid using pretty-printed output
26548 for dump purposes. Passing
<literal>false
</literal> for
26549 the
<parameter>pretty
</parameter> parameter yields the same result as
26550 omitting the parameter.
26553 <table id=
"functions-info-index-column-props">
26554 <title>Index Column Properties
</title>
26557 <row><entry>Name
</entry><entry>Description
</entry></row>
26561 <entry><literal>asc
</literal></entry>
26562 <entry>Does the column sort in ascending order on a forward scan?
26566 <entry><literal>desc
</literal></entry>
26567 <entry>Does the column sort in descending order on a forward scan?
26571 <entry><literal>nulls_first
</literal></entry>
26572 <entry>Does the column sort with nulls first on a forward scan?
26576 <entry><literal>nulls_last
</literal></entry>
26577 <entry>Does the column sort with nulls last on a forward scan?
26581 <entry><literal>orderable
</literal></entry>
26582 <entry>Does the column possess any defined sort ordering?
26586 <entry><literal>distance_orderable
</literal></entry>
26587 <entry>Can the column be scanned in order by a
<quote>distance
</quote>
26588 operator, for example
<literal>ORDER BY col
<-
> constant
</literal> ?
26592 <entry><literal>returnable
</literal></entry>
26593 <entry>Can the column value be returned by an index-only scan?
26597 <entry><literal>search_array
</literal></entry>
26598 <entry>Does the column natively support
<literal>col = ANY(array)
</literal>
26603 <entry><literal>search_nulls
</literal></entry>
26604 <entry>Does the column support
<literal>IS NULL
</literal> and
26605 <literal>IS NOT NULL
</literal> searches?
26612 <table id=
"functions-info-index-props">
26613 <title>Index Properties
</title>
26616 <row><entry>Name
</entry><entry>Description
</entry></row>
26620 <entry><literal>clusterable
</literal></entry>
26621 <entry>Can the index be used in a
<literal>CLUSTER
</literal> command?
26625 <entry><literal>index_scan
</literal></entry>
26626 <entry>Does the index support plain (non-bitmap) scans?
26630 <entry><literal>bitmap_scan
</literal></entry>
26631 <entry>Does the index support bitmap scans?
26635 <entry><literal>backward_scan
</literal></entry>
26636 <entry>Can the scan direction be changed in mid-scan (to
26637 support
<literal>FETCH BACKWARD
</literal> on a cursor without
26638 needing materialization)?
26645 <table id=
"functions-info-indexam-props">
26646 <title>Index Access Method Properties
</title>
26649 <row><entry>Name
</entry><entry>Description
</entry></row>
26653 <entry><literal>can_order
</literal></entry>
26654 <entry>Does the access method support
<literal>ASC
</literal>,
26655 <literal>DESC
</literal> and related keywords in
26656 <literal>CREATE INDEX
</literal>?
26660 <entry><literal>can_unique
</literal></entry>
26661 <entry>Does the access method support unique indexes?
26665 <entry><literal>can_multi_col
</literal></entry>
26666 <entry>Does the access method support indexes with multiple columns?
26670 <entry><literal>can_exclude
</literal></entry>
26671 <entry>Does the access method support exclusion constraints?
26675 <entry><literal>can_include
</literal></entry>
26676 <entry>Does the access method support the
<literal>INCLUDE
</literal>
26677 clause of
<literal>CREATE INDEX
</literal>?
26684 <table id=
"functions-pg-settings-flags">
26685 <title>GUC Flags
</title>
26688 <row><entry>Flag
</entry><entry>Description
</entry></row>
26692 <entry><literal>EXPLAIN
</literal></entry>
26693 <entry>Parameters with this flag are included in
26694 <command>EXPLAIN (SETTINGS)
</command> commands.
26698 <entry><literal>NO_SHOW_ALL
</literal></entry>
26699 <entry>Parameters with this flag are excluded from
26700 <command>SHOW ALL
</command> commands.
26704 <entry><literal>NO_RESET
</literal></entry>
26705 <entry>Parameters with this flag do not support
26706 <command>RESET
</command> commands.
26710 <entry><literal>NO_RESET_ALL
</literal></entry>
26711 <entry>Parameters with this flag are excluded from
26712 <command>RESET ALL
</command> commands.
26716 <entry><literal>NOT_IN_SAMPLE
</literal></entry>
26717 <entry>Parameters with this flag are not included in
26718 <filename>postgresql.conf
</filename> by default.
26722 <entry><literal>RUNTIME_COMPUTED
</literal></entry>
26723 <entry>Parameters with this flag are runtime-computed ones.
26732 <sect2 id=
"functions-info-object">
26733 <title>Object Information and Addressing Functions
</title>
26736 <xref linkend=
"functions-info-object-table"/> lists functions related to
26737 database object identification and addressing.
26740 <table id=
"functions-info-object-table">
26741 <title>Object Information and Addressing Functions
</title>
26745 <entry role=
"func_table_entry"><para role=
"func_signature">
26756 <entry role=
"func_table_entry"><para role=
"func_signature">
26758 <primary>pg_get_acl
</primary>
26760 <function>pg_get_acl
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
26761 <returnvalue>aclitem[]
</returnvalue>
26764 Returns the
<acronym>ACL
</acronym> for a database object, specified
26765 by catalog OID, object OID and sub-object ID. This function returns
26766 <literal>NULL
</literal> values for undefined objects.
26771 <entry role=
"func_table_entry"><para role=
"func_signature">
26773 <primary>pg_describe_object
</primary>
26775 <function>pg_describe_object
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
26776 <returnvalue>text
</returnvalue>
26779 Returns a textual description of a database object identified by
26780 catalog OID, object OID, and sub-object ID (such as a column number
26781 within a table; the sub-object ID is zero when referring to a whole
26782 object). This description is intended to be human-readable, and might
26783 be translated, depending on server configuration. This is especially
26784 useful to determine the identity of an object referenced in the
26785 <structname>pg_depend
</structname> catalog. This function returns
26786 <literal>NULL
</literal> values for undefined objects.
26791 <entry role=
"func_table_entry"><para role=
"func_signature">
26793 <primary>pg_identify_object
</primary>
26795 <function>pg_identify_object
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
26796 <returnvalue>record
</returnvalue>
26797 (
<parameter>type
</parameter> <type>text
</type>,
26798 <parameter>schema
</parameter> <type>text
</type>,
26799 <parameter>name
</parameter> <type>text
</type>,
26800 <parameter>identity
</parameter> <type>text
</type> )
26803 Returns a row containing enough information to uniquely identify the
26804 database object specified by catalog OID, object OID and sub-object
26806 This information is intended to be machine-readable, and is never
26808 <parameter>type
</parameter> identifies the type of database object;
26809 <parameter>schema
</parameter> is the schema name that the object
26810 belongs in, or
<literal>NULL
</literal> for object types that do not
26812 <parameter>name
</parameter> is the name of the object, quoted if
26813 necessary, if the name (along with schema name, if pertinent) is
26814 sufficient to uniquely identify the object,
26815 otherwise
<literal>NULL
</literal>;
26816 <parameter>identity
</parameter> is the complete object identity, with
26817 the precise format depending on object type, and each name within the
26818 format being schema-qualified and quoted as necessary. Undefined
26819 objects are identified with
<literal>NULL
</literal> values.
26824 <entry role=
"func_table_entry"><para role=
"func_signature">
26826 <primary>pg_identify_object_as_address
</primary>
26828 <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> )
26829 <returnvalue>record
</returnvalue>
26830 (
<parameter>type
</parameter> <type>text
</type>,
26831 <parameter>object_names
</parameter> <type>text[]
</type>,
26832 <parameter>object_args
</parameter> <type>text[]
</type> )
26835 Returns a row containing enough information to uniquely identify the
26836 database object specified by catalog OID, object OID and sub-object
26838 The returned information is independent of the current server, that
26839 is, it could be used to identify an identically named object in
26841 <parameter>type
</parameter> identifies the type of database object;
26842 <parameter>object_names
</parameter> and
26843 <parameter>object_args
</parameter>
26844 are text arrays that together form a reference to the object.
26845 These three values can be passed
26846 to
<function>pg_get_object_address
</function> to obtain the internal
26847 address of the object.
26852 <entry role=
"func_table_entry"><para role=
"func_signature">
26854 <primary>pg_get_object_address
</primary>
26856 <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> )
26857 <returnvalue>record
</returnvalue>
26858 (
<parameter>classid
</parameter> <type>oid
</type>,
26859 <parameter>objid
</parameter> <type>oid
</type>,
26860 <parameter>objsubid
</parameter> <type>integer
</type> )
26863 Returns a row containing enough information to uniquely identify the
26864 database object specified by a type code and object name and argument
26866 The returned values are the ones that would be used in system catalogs
26867 such as
<structname>pg_depend
</structname>; they can be passed to
26868 other system functions such as
<function>pg_describe_object
</function>
26869 or
<function>pg_identify_object
</function>.
26870 <parameter>classid
</parameter> is the OID of the system catalog
26871 containing the object;
26872 <parameter>objid
</parameter> is the OID of the object itself, and
26873 <parameter>objsubid
</parameter> is the sub-object ID, or zero if none.
26874 This function is the inverse
26875 of
<function>pg_identify_object_as_address
</function>.
26876 Undefined objects are identified with
<literal>NULL
</literal> values.
26884 <function>pg_get_acl
</function> is useful for retrieving and inspecting
26885 the privileges associated with database objects without looking at
26886 specific catalogs. For example, to retrieve all the granted privileges
26887 on objects in the current database:
26890 (pg_identify_object(s.classid,s.objid,s.objsubid)).*,
26891 pg_catalog.pg_get_acl(s.classid,s.objid,s.objsubid) AS acl
26892 FROM pg_catalog.pg_shdepend AS s
26893 JOIN pg_catalog.pg_database AS d
26894 ON d.datname = current_database() AND
26896 JOIN pg_catalog.pg_authid AS a
26897 ON a.oid = s.refobjid AND
26898 s.refclassid = 'pg_authid'::regclass
26899 WHERE s.deptype = 'a';
26900 -[ RECORD
1 ]-----------------------------------------
26904 identity | public.testtab
26905 acl | {postgres=arwdDxtm/postgres,foo=r/postgres}
26911 <sect2 id=
"functions-info-comment">
26912 <title>Comment Information Functions
</title>
26915 <primary>comment
</primary>
26916 <secondary sortas=
"database objects">about database objects
</secondary>
26920 The functions shown in
<xref linkend=
"functions-info-comment-table"/>
26921 extract comments previously stored with the
<xref linkend=
"sql-comment"/>
26922 command. A null value is returned if no
26923 comment could be found for the specified parameters.
26926 <table id=
"functions-info-comment-table">
26927 <title>Comment Information Functions
</title>
26931 <entry role=
"func_table_entry"><para role=
"func_signature">
26942 <entry role=
"func_table_entry"><para role=
"func_signature">
26944 <primary>col_description
</primary>
26946 <function>col_description
</function> (
<parameter>table
</parameter> <type>oid
</type>,
<parameter>column
</parameter> <type>integer
</type> )
26947 <returnvalue>text
</returnvalue>
26950 Returns the comment for a table column, which is specified by the OID
26951 of its table and its column number.
26952 (
<function>obj_description
</function> cannot be used for table
26953 columns, since columns do not have OIDs of their own.)
26958 <entry role=
"func_table_entry"><para role=
"func_signature">
26960 <primary>obj_description
</primary>
26962 <function>obj_description
</function> (
<parameter>object
</parameter> <type>oid
</type>,
<parameter>catalog
</parameter> <type>name
</type> )
26963 <returnvalue>text
</returnvalue>
26966 Returns the comment for a database object specified by its OID and the
26967 name of the containing system catalog. For
26968 example,
<literal>obj_description(
123456, 'pg_class')
</literal> would
26969 retrieve the comment for the table with OID
123456.
26974 <entry role=
"func_table_entry"><para role=
"func_signature">
26975 <function>obj_description
</function> (
<parameter>object
</parameter> <type>oid
</type> )
26976 <returnvalue>text
</returnvalue>
26979 Returns the comment for a database object specified by its OID alone.
26980 This is
<emphasis>deprecated
</emphasis> since there is no guarantee
26981 that OIDs are unique across different system catalogs; therefore, the
26982 wrong comment might be returned.
26987 <entry role=
"func_table_entry"><para role=
"func_signature">
26989 <primary>shobj_description
</primary>
26991 <function>shobj_description
</function> (
<parameter>object
</parameter> <type>oid
</type>,
<parameter>catalog
</parameter> <type>name
</type> )
26992 <returnvalue>text
</returnvalue>
26995 Returns the comment for a shared database object specified by its OID
26996 and the name of the containing system catalog. This is just
26997 like
<function>obj_description
</function> except that it is used for
26998 retrieving comments on shared objects (that is, databases, roles, and
26999 tablespaces). Some system catalogs are global to all databases within
27000 each cluster, and the descriptions for objects in them are stored
27010 <sect2 id=
"functions-info-validity">
27011 <title>Data Validity Checking Functions
</title>
27014 The functions shown in
<xref linkend=
"functions-info-validity-table"/>
27015 can be helpful for checking validity of proposed input data.
27018 <table id=
"functions-info-validity-table">
27019 <title>Data Validity Checking Functions
</title>
27023 <entry role=
"func_table_entry"><para role=
"func_signature">
27037 <entry role=
"func_table_entry"><para role=
"func_signature">
27039 <primary>pg_input_is_valid
</primary>
27041 <function>pg_input_is_valid
</function> (
27042 <parameter>string
</parameter> <type>text
</type>,
27043 <parameter>type
</parameter> <type>text
</type>
27045 <returnvalue>boolean
</returnvalue>
27048 Tests whether the given
<parameter>string
</parameter> is valid
27049 input for the specified data type, returning true or false.
27052 This function will only work as desired if the data type's input
27053 function has been updated to report invalid input as
27054 a
<quote>soft
</quote> error. Otherwise, invalid input will abort
27055 the transaction, just as if the string had been cast to the type
27059 <literal>pg_input_is_valid('
42', 'integer')
</literal>
27060 <returnvalue>t
</returnvalue>
27063 <literal>pg_input_is_valid('
42000000000', 'integer')
</literal>
27064 <returnvalue>f
</returnvalue>
27067 <literal>pg_input_is_valid('
1234.567', 'numeric(
7,
4)')
</literal>
27068 <returnvalue>f
</returnvalue>
27072 <entry role=
"func_table_entry"><para role=
"func_signature">
27074 <primary>pg_input_error_info
</primary>
27076 <function>pg_input_error_info
</function> (
27077 <parameter>string
</parameter> <type>text
</type>,
27078 <parameter>type
</parameter> <type>text
</type>
27080 <returnvalue>record
</returnvalue>
27081 (
<parameter>message
</parameter> <type>text
</type>,
27082 <parameter>detail
</parameter> <type>text
</type>,
27083 <parameter>hint
</parameter> <type>text
</type>,
27084 <parameter>sql_error_code
</parameter> <type>text
</type> )
27087 Tests whether the given
<parameter>string
</parameter> is valid
27088 input for the specified data type; if not, return the details of
27089 the error that would have been thrown. If the input is valid, the
27090 results are NULL. The inputs are the same as
27091 for
<function>pg_input_is_valid
</function>.
27094 This function will only work as desired if the data type's input
27095 function has been updated to report invalid input as
27096 a
<quote>soft
</quote> error. Otherwise, invalid input will abort
27097 the transaction, just as if the string had been cast to the type
27101 <literal>SELECT * FROM pg_input_error_info('
42000000000', 'integer')
</literal>
27102 <returnvalue></returnvalue>
27104 message | detail | hint | sql_error_code
27105 ------------------------------------------------------+--------+------+----------------
27106 value
"42000000000" is out of range for type integer | | |
22003
27116 <sect2 id=
"functions-info-snapshot">
27117 <title>Transaction ID and Snapshot Information Functions
</title>
27120 The functions shown in
<xref linkend=
"functions-pg-snapshot"/>
27121 provide server transaction information in an exportable form. The main
27122 use of these functions is to determine which transactions were committed
27123 between two snapshots.
27126 <table id=
"functions-pg-snapshot">
27127 <title>Transaction ID and Snapshot Information Functions
</title>
27131 <entry role=
"func_table_entry"><para role=
"func_signature">
27142 <entry role=
"func_table_entry"><para role=
"func_signature">
27144 <primary>age
</primary>
27146 <function>age
</function> (
<type>xid
</type> )
27147 <returnvalue>integer
</returnvalue>
27150 Returns the number of transactions between the supplied
27151 transaction id and the current transaction counter.
27156 <entry role=
"func_table_entry"><para role=
"func_signature">
27158 <primary>mxid_age
</primary>
27160 <function>mxid_age
</function> (
<type>xid
</type> )
27161 <returnvalue>integer
</returnvalue>
27164 Returns the number of multixacts IDs between the supplied
27165 multixact ID and the current multixacts counter.
27170 <entry role=
"func_table_entry"><para role=
"func_signature">
27172 <primary>pg_current_xact_id
</primary>
27174 <function>pg_current_xact_id
</function> ()
27175 <returnvalue>xid8
</returnvalue>
27178 Returns the current transaction's ID. It will assign a new one if the
27179 current transaction does not have one already (because it has not
27180 performed any database updates); see
<xref
27181 linkend=
"transaction-id"/> for details. If executed in a
27182 subtransaction, this will return the top-level transaction ID;
27183 see
<xref linkend=
"subxacts"/> for details.
27188 <entry role=
"func_table_entry"><para role=
"func_signature">
27190 <primary>pg_current_xact_id_if_assigned
</primary>
27192 <function>pg_current_xact_id_if_assigned
</function> ()
27193 <returnvalue>xid8
</returnvalue>
27196 Returns the current transaction's ID, or
<literal>NULL
</literal> if no
27197 ID is assigned yet. (It's best to use this variant if the transaction
27198 might otherwise be read-only, to avoid unnecessary consumption of an
27200 If executed in a subtransaction, this will return the top-level
27206 <entry role=
"func_table_entry"><para role=
"func_signature">
27208 <primary>pg_xact_status
</primary>
27210 <function>pg_xact_status
</function> (
<type>xid8
</type> )
27211 <returnvalue>text
</returnvalue>
27214 Reports the commit status of a recent transaction.
27215 The result is one of
<literal>in progress
</literal>,
27216 <literal>committed
</literal>, or
<literal>aborted
</literal>,
27217 provided that the transaction is recent enough that the system retains
27218 the commit status of that transaction.
27219 If it is old enough that no references to the transaction survive in
27220 the system and the commit status information has been discarded, the
27221 result is
<literal>NULL
</literal>.
27222 Applications might use this function, for example, to determine
27223 whether their transaction committed or aborted after the application
27224 and database server become disconnected while
27225 a
<literal>COMMIT
</literal> is in progress.
27226 Note that prepared transactions are reported as
<literal>in
27227 progress
</literal>; applications must check
<link
27228 linkend=
"view-pg-prepared-xacts"><structname>pg_prepared_xacts
</structname></link>
27229 if they need to determine whether a transaction ID belongs to a
27230 prepared transaction.
27235 <entry role=
"func_table_entry"><para role=
"func_signature">
27237 <primary>pg_current_snapshot
</primary>
27239 <function>pg_current_snapshot
</function> ()
27240 <returnvalue>pg_snapshot
</returnvalue>
27243 Returns a current
<firstterm>snapshot
</firstterm>, a data structure
27244 showing which transaction IDs are now in-progress.
27245 Only top-level transaction IDs are included in the snapshot;
27246 subtransaction IDs are not shown; see
<xref linkend=
"subxacts"/>
27252 <entry role=
"func_table_entry"><para role=
"func_signature">
27254 <primary>pg_snapshot_xip
</primary>
27256 <function>pg_snapshot_xip
</function> (
<type>pg_snapshot
</type> )
27257 <returnvalue>setof xid8
</returnvalue>
27260 Returns the set of in-progress transaction IDs contained in a snapshot.
27265 <entry role=
"func_table_entry"><para role=
"func_signature">
27267 <primary>pg_snapshot_xmax
</primary>
27269 <function>pg_snapshot_xmax
</function> (
<type>pg_snapshot
</type> )
27270 <returnvalue>xid8
</returnvalue>
27273 Returns the
<structfield>xmax
</structfield> of a snapshot.
27278 <entry role=
"func_table_entry"><para role=
"func_signature">
27280 <primary>pg_snapshot_xmin
</primary>
27282 <function>pg_snapshot_xmin
</function> (
<type>pg_snapshot
</type> )
27283 <returnvalue>xid8
</returnvalue>
27286 Returns the
<structfield>xmin
</structfield> of a snapshot.
27291 <entry role=
"func_table_entry"><para role=
"func_signature">
27293 <primary>pg_visible_in_snapshot
</primary>
27295 <function>pg_visible_in_snapshot
</function> (
<type>xid8
</type>,
<type>pg_snapshot
</type> )
27296 <returnvalue>boolean
</returnvalue>
27299 Is the given transaction ID
<firstterm>visible
</firstterm> according
27300 to this snapshot (that is, was it completed before the snapshot was
27301 taken)? Note that this function will not give the correct answer for
27302 a subtransaction ID (subxid); see
<xref linkend=
"subxacts"/> for
27311 The internal transaction ID type
<type>xid
</type> is
32 bits wide and
27312 wraps around every
4 billion transactions. However,
27313 the functions shown in
<xref linkend=
"functions-pg-snapshot"/>, except
27314 <function>age
</function> and
<function>mxid_age
</function>, use a
27315 64-bit type
<type>xid8
</type> that does not wrap around during the life
27316 of an installation and can be converted to
<type>xid
</type> by casting if
27317 required; see
<xref linkend=
"transaction-id"/> for details.
27318 The data type
<type>pg_snapshot
</type> stores information about
27319 transaction ID visibility at a particular moment in time. Its components
27320 are described in
<xref linkend=
"functions-pg-snapshot-parts"/>.
27321 <type>pg_snapshot
</type>'s textual representation is
27322 <literal><replaceable>xmin
</replaceable>:
<replaceable>xmax
</replaceable>:
<replaceable>xip_list
</replaceable></literal>.
27323 For example
<literal>10:
20:
10,
14,
15</literal> means
27324 <literal>xmin=
10, xmax=
20, xip_list=
10,
14,
15</literal>.
27327 <table id=
"functions-pg-snapshot-parts">
27328 <title>Snapshot Components
</title>
27332 <entry>Name
</entry>
27333 <entry>Description
</entry>
27339 <entry><structfield>xmin
</structfield></entry>
27341 Lowest transaction ID that was still active. All transaction IDs
27342 less than
<structfield>xmin
</structfield> are either committed and visible,
27343 or rolled back and dead.
27348 <entry><structfield>xmax
</structfield></entry>
27350 One past the highest completed transaction ID. All transaction IDs
27351 greater than or equal to
<structfield>xmax
</structfield> had not yet
27352 completed as of the time of the snapshot, and thus are invisible.
27357 <entry><structfield>xip_list
</structfield></entry>
27359 Transactions in progress at the time of the snapshot. A transaction
27360 ID that is
<literal>xmin
<=
<replaceable>X
</replaceable> <
27361 xmax
</literal> and not in this list was already completed at the time
27362 of the snapshot, and thus is either visible or dead according to its
27363 commit status. This list does not include the transaction IDs of
27364 subtransactions (subxids).
27372 In releases of
<productname>PostgreSQL
</productname> before
13 there was
27373 no
<type>xid8
</type> type, so variants of these functions were provided
27374 that used
<type>bigint
</type> to represent a
64-bit XID, with a
27375 correspondingly distinct snapshot data type
<type>txid_snapshot
</type>.
27376 These older functions have
<literal>txid
</literal> in their names. They
27377 are still supported for backward compatibility, but may be removed from a
27378 future release. See
<xref linkend=
"functions-txid-snapshot"/>.
27381 <table id=
"functions-txid-snapshot">
27382 <title>Deprecated Transaction ID and Snapshot Information Functions
</title>
27386 <entry role=
"func_table_entry"><para role=
"func_signature">
27398 <entry role=
"func_table_entry"><para role=
"func_signature">
27400 <primary>txid_current
</primary>
27402 <function>txid_current
</function> ()
27403 <returnvalue>bigint
</returnvalue>
27406 See
<function>pg_current_xact_id()
</function>.
27411 <entry role=
"func_table_entry"><para role=
"func_signature">
27413 <primary>txid_current_if_assigned
</primary>
27415 <function>txid_current_if_assigned
</function> ()
27416 <returnvalue>bigint
</returnvalue>
27419 See
<function>pg_current_xact_id_if_assigned()
</function>.
27424 <entry role=
"func_table_entry"><para role=
"func_signature">
27426 <primary>txid_current_snapshot
</primary>
27428 <function>txid_current_snapshot
</function> ()
27429 <returnvalue>txid_snapshot
</returnvalue>
27432 See
<function>pg_current_snapshot()
</function>.
27437 <entry role=
"func_table_entry"><para role=
"func_signature">
27439 <primary>txid_snapshot_xip
</primary>
27441 <function>txid_snapshot_xip
</function> (
<type>txid_snapshot
</type> )
27442 <returnvalue>setof bigint
</returnvalue>
27445 See
<function>pg_snapshot_xip()
</function>.
27450 <entry role=
"func_table_entry"><para role=
"func_signature">
27452 <primary>txid_snapshot_xmax
</primary>
27454 <function>txid_snapshot_xmax
</function> (
<type>txid_snapshot
</type> )
27455 <returnvalue>bigint
</returnvalue>
27458 See
<function>pg_snapshot_xmax()
</function>.
27463 <entry role=
"func_table_entry"><para role=
"func_signature">
27465 <primary>txid_snapshot_xmin
</primary>
27467 <function>txid_snapshot_xmin
</function> (
<type>txid_snapshot
</type> )
27468 <returnvalue>bigint
</returnvalue>
27471 See
<function>pg_snapshot_xmin()
</function>.
27476 <entry role=
"func_table_entry"><para role=
"func_signature">
27478 <primary>txid_visible_in_snapshot
</primary>
27480 <function>txid_visible_in_snapshot
</function> (
<type>bigint
</type>,
<type>txid_snapshot
</type> )
27481 <returnvalue>boolean
</returnvalue>
27484 See
<function>pg_visible_in_snapshot()
</function>.
27489 <entry role=
"func_table_entry"><para role=
"func_signature">
27491 <primary>txid_status
</primary>
27493 <function>txid_status
</function> (
<type>bigint
</type> )
27494 <returnvalue>text
</returnvalue>
27497 See
<function>pg_xact_status()
</function>.
27506 <sect2 id=
"functions-info-commit-timestamp">
27507 <title>Committed Transaction Information Functions
</title>
27510 The functions shown in
<xref linkend=
"functions-commit-timestamp"/>
27511 provide information about when past transactions were committed.
27512 They only provide useful data when the
27513 <xref linkend=
"guc-track-commit-timestamp"/> configuration option is
27514 enabled, and only for transactions that were committed after it was
27515 enabled. Commit timestamp information is routinely removed during
27519 <table id=
"functions-commit-timestamp">
27520 <title>Committed Transaction Information Functions
</title>
27524 <entry role=
"func_table_entry"><para role=
"func_signature">
27535 <entry role=
"func_table_entry"><para role=
"func_signature">
27537 <primary>pg_xact_commit_timestamp
</primary>
27539 <function>pg_xact_commit_timestamp
</function> (
<type>xid
</type> )
27540 <returnvalue>timestamp with time zone
</returnvalue>
27543 Returns the commit timestamp of a transaction.
27548 <entry role=
"func_table_entry"><para role=
"func_signature">
27550 <primary>pg_xact_commit_timestamp_origin
</primary>
27552 <function>pg_xact_commit_timestamp_origin
</function> (
<type>xid
</type> )
27553 <returnvalue>record
</returnvalue>
27554 (
<parameter>timestamp
</parameter> <type>timestamp with time zone
</type>,
27555 <parameter>roident
</parameter> <type>oid
</type>)
27558 Returns the commit timestamp and replication origin of a transaction.
27563 <entry role=
"func_table_entry"><para role=
"func_signature">
27565 <primary>pg_last_committed_xact
</primary>
27567 <function>pg_last_committed_xact
</function> ()
27568 <returnvalue>record
</returnvalue>
27569 (
<parameter>xid
</parameter> <type>xid
</type>,
27570 <parameter>timestamp
</parameter> <type>timestamp with time zone
</type>,
27571 <parameter>roident
</parameter> <type>oid
</type> )
27574 Returns the transaction ID, commit timestamp and replication origin
27575 of the latest committed transaction.
27584 <sect2 id=
"functions-info-controldata">
27585 <title>Control Data Functions
</title>
27588 The functions shown in
<xref linkend=
"functions-controldata"/>
27589 print information initialized during
<command>initdb
</command>, such
27590 as the catalog version. They also show information about write-ahead
27591 logging and checkpoint processing. This information is cluster-wide,
27592 not specific to any one database. These functions provide most of the same
27593 information, from the same source, as the
27594 <xref linkend=
"app-pgcontroldata"/> application.
27597 <table id=
"functions-controldata">
27598 <title>Control Data Functions
</title>
27602 <entry role=
"func_table_entry"><para role=
"func_signature">
27613 <entry role=
"func_table_entry"><para role=
"func_signature">
27615 <primary>pg_control_checkpoint
</primary>
27617 <function>pg_control_checkpoint
</function> ()
27618 <returnvalue>record
</returnvalue>
27621 Returns information about current checkpoint state, as shown in
27622 <xref linkend=
"functions-pg-control-checkpoint"/>.
27627 <entry role=
"func_table_entry"><para role=
"func_signature">
27629 <primary>pg_control_system
</primary>
27631 <function>pg_control_system
</function> ()
27632 <returnvalue>record
</returnvalue>
27635 Returns information about current control file state, as shown in
27636 <xref linkend=
"functions-pg-control-system"/>.
27641 <entry role=
"func_table_entry"><para role=
"func_signature">
27643 <primary>pg_control_init
</primary>
27645 <function>pg_control_init
</function> ()
27646 <returnvalue>record
</returnvalue>
27649 Returns information about cluster initialization state, as shown in
27650 <xref linkend=
"functions-pg-control-init"/>.
27655 <entry role=
"func_table_entry"><para role=
"func_signature">
27657 <primary>pg_control_recovery
</primary>
27659 <function>pg_control_recovery
</function> ()
27660 <returnvalue>record
</returnvalue>
27663 Returns information about recovery state, as shown in
27664 <xref linkend=
"functions-pg-control-recovery"/>.
27671 <table id=
"functions-pg-control-checkpoint">
27672 <title><function>pg_control_checkpoint
</function> Output Columns
</title>
27676 <entry>Column Name
</entry>
27677 <entry>Data Type
</entry>
27684 <entry><structfield>checkpoint_lsn
</structfield></entry>
27685 <entry><type>pg_lsn
</type></entry>
27689 <entry><structfield>redo_lsn
</structfield></entry>
27690 <entry><type>pg_lsn
</type></entry>
27694 <entry><structfield>redo_wal_file
</structfield></entry>
27695 <entry><type>text
</type></entry>
27699 <entry><structfield>timeline_id
</structfield></entry>
27700 <entry><type>integer
</type></entry>
27704 <entry><structfield>prev_timeline_id
</structfield></entry>
27705 <entry><type>integer
</type></entry>
27709 <entry><structfield>full_page_writes
</structfield></entry>
27710 <entry><type>boolean
</type></entry>
27714 <entry><structfield>next_xid
</structfield></entry>
27715 <entry><type>text
</type></entry>
27719 <entry><structfield>next_oid
</structfield></entry>
27720 <entry><type>oid
</type></entry>
27724 <entry><structfield>next_multixact_id
</structfield></entry>
27725 <entry><type>xid
</type></entry>
27729 <entry><structfield>next_multi_offset
</structfield></entry>
27730 <entry><type>xid
</type></entry>
27734 <entry><structfield>oldest_xid
</structfield></entry>
27735 <entry><type>xid
</type></entry>
27739 <entry><structfield>oldest_xid_dbid
</structfield></entry>
27740 <entry><type>oid
</type></entry>
27744 <entry><structfield>oldest_active_xid
</structfield></entry>
27745 <entry><type>xid
</type></entry>
27749 <entry><structfield>oldest_multi_xid
</structfield></entry>
27750 <entry><type>xid
</type></entry>
27754 <entry><structfield>oldest_multi_dbid
</structfield></entry>
27755 <entry><type>oid
</type></entry>
27759 <entry><structfield>oldest_commit_ts_xid
</structfield></entry>
27760 <entry><type>xid
</type></entry>
27764 <entry><structfield>newest_commit_ts_xid
</structfield></entry>
27765 <entry><type>xid
</type></entry>
27769 <entry><structfield>checkpoint_time
</structfield></entry>
27770 <entry><type>timestamp with time zone
</type></entry>
27777 <table id=
"functions-pg-control-system">
27778 <title><function>pg_control_system
</function> Output Columns
</title>
27782 <entry>Column Name
</entry>
27783 <entry>Data Type
</entry>
27790 <entry><structfield>pg_control_version
</structfield></entry>
27791 <entry><type>integer
</type></entry>
27795 <entry><structfield>catalog_version_no
</structfield></entry>
27796 <entry><type>integer
</type></entry>
27800 <entry><structfield>system_identifier
</structfield></entry>
27801 <entry><type>bigint
</type></entry>
27805 <entry><structfield>pg_control_last_modified
</structfield></entry>
27806 <entry><type>timestamp with time zone
</type></entry>
27813 <table id=
"functions-pg-control-init">
27814 <title><function>pg_control_init
</function> Output Columns
</title>
27818 <entry>Column Name
</entry>
27819 <entry>Data Type
</entry>
27826 <entry><structfield>max_data_alignment
</structfield></entry>
27827 <entry><type>integer
</type></entry>
27831 <entry><structfield>database_block_size
</structfield></entry>
27832 <entry><type>integer
</type></entry>
27836 <entry><structfield>blocks_per_segment
</structfield></entry>
27837 <entry><type>integer
</type></entry>
27841 <entry><structfield>wal_block_size
</structfield></entry>
27842 <entry><type>integer
</type></entry>
27846 <entry><structfield>bytes_per_wal_segment
</structfield></entry>
27847 <entry><type>integer
</type></entry>
27851 <entry><structfield>max_identifier_length
</structfield></entry>
27852 <entry><type>integer
</type></entry>
27856 <entry><structfield>max_index_columns
</structfield></entry>
27857 <entry><type>integer
</type></entry>
27861 <entry><structfield>max_toast_chunk_size
</structfield></entry>
27862 <entry><type>integer
</type></entry>
27866 <entry><structfield>large_object_chunk_size
</structfield></entry>
27867 <entry><type>integer
</type></entry>
27871 <entry><structfield>float8_pass_by_value
</structfield></entry>
27872 <entry><type>boolean
</type></entry>
27876 <entry><structfield>data_page_checksum_version
</structfield></entry>
27877 <entry><type>integer
</type></entry>
27884 <table id=
"functions-pg-control-recovery">
27885 <title><function>pg_control_recovery
</function> Output Columns
</title>
27889 <entry>Column Name
</entry>
27890 <entry>Data Type
</entry>
27897 <entry><structfield>min_recovery_end_lsn
</structfield></entry>
27898 <entry><type>pg_lsn
</type></entry>
27902 <entry><structfield>min_recovery_end_timeline
</structfield></entry>
27903 <entry><type>integer
</type></entry>
27907 <entry><structfield>backup_start_lsn
</structfield></entry>
27908 <entry><type>pg_lsn
</type></entry>
27912 <entry><structfield>backup_end_lsn
</structfield></entry>
27913 <entry><type>pg_lsn
</type></entry>
27917 <entry><structfield>end_of_backup_record_required
</structfield></entry>
27918 <entry><type>boolean
</type></entry>
27927 <sect2 id=
"functions-info-version">
27928 <title>Version Information Functions
</title>
27931 The functions shown in
<xref linkend=
"functions-version"/>
27932 print version information.
27935 <table id=
"functions-version">
27936 <title>Version Information Functions
</title>
27940 <entry role=
"func_table_entry"><para role=
"func_signature">
27951 <entry role=
"func_table_entry"><para role=
"func_signature">
27953 <primary>version
</primary>
27955 <function>version
</function> ()
27956 <returnvalue>text
</returnvalue>
27959 Returns a string describing the
<productname>PostgreSQL
</productname>
27960 server's version. You can also get this information from
27961 <xref linkend=
"guc-server-version"/>, or for a machine-readable
27962 version use
<xref linkend=
"guc-server-version-num"/>. Software
27963 developers should use
<varname>server_version_num
</varname> (available
27964 since
8.2) or
<xref linkend=
"libpq-PQserverVersion"/> instead of
27965 parsing the text version.
27970 <entry role=
"func_table_entry"><para role=
"func_signature">
27972 <primary>unicode_version
</primary>
27974 <function>unicode_version
</function> ()
27975 <returnvalue>text
</returnvalue>
27978 Returns a string representing the version of Unicode used by
27979 <productname>PostgreSQL
</productname>.
27983 <entry role=
"func_table_entry"><para role=
"func_signature">
27985 <primary>icu_unicode_version
</primary>
27987 <function>icu_unicode_version
</function> ()
27988 <returnvalue>text
</returnvalue>
27991 Returns a string representing the version of Unicode used by ICU, if
27992 the server was built with ICU support; otherwise returns
27993 <literal>NULL
</literal> </para></entry>
28001 <sect2 id=
"functions-info-wal-summary">
28002 <title>WAL Summarization Information Functions
</title>
28005 The functions shown in
<xref linkend=
"functions-wal-summary"/>
28006 print information about the status of WAL summarization.
28007 See
<xref linkend=
"guc-summarize-wal" />.
28010 <table id=
"functions-wal-summary">
28011 <title>WAL Summarization Information Functions
</title>
28015 <entry role=
"func_table_entry"><para role=
"func_signature">
28026 <entry role=
"func_table_entry"><para role=
"func_signature">
28028 <primary>pg_available_wal_summaries
</primary>
28030 <function>pg_available_wal_summaries
</function> ()
28031 <returnvalue>setof record
</returnvalue>
28032 (
<parameter>tli
</parameter> <type>bigint
</type>,
28033 <parameter>start_lsn
</parameter> <type>pg_lsn
</type>,
28034 <parameter>end_lsn
</parameter> <type>pg_lsn
</type> )
28037 Returns information about the WAL summary files present in the
28038 data directory, under
<literal>pg_wal/summaries
</literal>.
28039 One row will be returned per WAL summary file. Each file summarizes
28040 WAL on the indicated TLI within the indicated LSN range. This function
28041 might be useful to determine whether enough WAL summaries are present
28042 on the server to take an incremental backup based on some prior
28043 backup whose start LSN is known.
28048 <entry role=
"func_table_entry"><para role=
"func_signature">
28050 <primary>pg_wal_summary_contents
</primary>
28052 <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> )
28053 <returnvalue>setof record
</returnvalue>
28054 (
<parameter>relfilenode
</parameter> <type>oid
</type>,
28055 <parameter>reltablespace
</parameter> <type>oid
</type>,
28056 <parameter>reldatabase
</parameter> <type>oid
</type>,
28057 <parameter>relforknumber
</parameter> <type>smallint
</type>,
28058 <parameter>relblocknumber
</parameter> <type>bigint
</type>,
28059 <parameter>is_limit_block
</parameter> <type>boolean
</type> )
28062 Returns one information about the contents of a single WAL summary file
28063 identified by TLI and starting and ending LSNs. Each row with
28064 <literal>is_limit_block
</literal> false indicates that the block
28065 identified by the remaining output columns was modified by at least
28066 one WAL record within the range of records summarized by this file.
28067 Each row with
<literal>is_limit_block
</literal> true indicates either
28068 that (a) the relation fork was truncated to the length given by
28069 <literal>relblocknumber
</literal> within the relevant range of WAL
28070 records or (b) that the relation fork was created or dropped within
28071 the relevant range of WAL records; in such cases,
28072 <literal>relblocknumber
</literal> will be zero.
28077 <entry role=
"func_table_entry"><para role=
"func_signature">
28079 <primary>pg_get_wal_summarizer_state
</primary>
28081 <function>pg_get_wal_summarizer_state
</function> ()
28082 <returnvalue>record
</returnvalue>
28083 (
<parameter>summarized_tli
</parameter> <type>bigint
</type>,
28084 <parameter>summarized_lsn
</parameter> <type>pg_lsn
</type>,
28085 <parameter>pending_lsn
</parameter> <type>pg_lsn
</type>,
28086 <parameter>summarizer_pid
</parameter> <type>int
</type> )
28089 Returns information about the progress of the WAL summarizer. If the
28090 WAL summarizer has never run since the instance was started, then
28091 <literal>summarized_tli
</literal> and
<literal>summarized_lsn
</literal>
28092 will be
<literal>0</literal> and
<literal>0/
0</literal> respectively;
28093 otherwise, they will be the TLI and ending LSN of the last WAL summary
28094 file written to disk. If the WAL summarizer is currently running,
28095 <literal>pending_lsn
</literal> will be the ending LSN of the last
28096 record that it has consumed, which must always be greater than or
28097 equal to
<literal>summarized_lsn
</literal>; if the WAL summarizer is
28098 not running, it will be equal to
<literal>summarized_lsn
</literal>.
28099 <literal>summarizer_pid
</literal> is the PID of the WAL summarizer
28100 process, if it is running, and otherwise NULL.
28103 As a special exception, the WAL summarizer will refuse to generate
28104 WAL summary files if run on WAL generated under
28105 <literal>wal_level=minimal
</literal>, since such summaries would be
28106 unsafe to use as the basis for an incremental backup. In this case,
28107 the fields above will continue to advance as if summaries were being
28108 generated, but nothing will be written to disk. Once the summarizer
28109 reaches WAL generated while
<literal>wal_level
</literal> was set
28110 to
<literal>replica
</literal> or higher, it will resume writing
28122 <sect1 id=
"functions-admin">
28123 <title>System Administration Functions
</title>
28126 The functions described in this section are used to control and
28127 monitor a
<productname>PostgreSQL
</productname> installation.
28130 <sect2 id=
"functions-admin-set">
28131 <title>Configuration Settings Functions
</title>
28134 <primary>SET
</primary>
28138 <primary>SHOW
</primary>
28142 <primary>configuration
</primary>
28143 <secondary sortas=
"server">of the server
</secondary>
28144 <tertiary>functions
</tertiary>
28148 <xref linkend=
"functions-admin-set-table"/> shows the functions
28149 available to query and alter run-time configuration parameters.
28152 <table id=
"functions-admin-set-table">
28153 <title>Configuration Settings Functions
</title>
28157 <entry role=
"func_table_entry"><para role=
"func_signature">
28171 <entry role=
"func_table_entry"><para role=
"func_signature">
28173 <primary>current_setting
</primary>
28175 <function>current_setting
</function> (
<parameter>setting_name
</parameter> <type>text
</type> <optional>,
<parameter>missing_ok
</parameter> <type>boolean
</type> </optional> )
28176 <returnvalue>text
</returnvalue>
28179 Returns the current value of the
28180 setting
<parameter>setting_name
</parameter>. If there is no such
28181 setting,
<function>current_setting
</function> throws an error
28182 unless
<parameter>missing_ok
</parameter> is supplied and
28183 is
<literal>true
</literal> (in which case NULL is returned).
28184 This function corresponds to
28185 the
<acronym>SQL
</acronym> command
<xref linkend=
"sql-show"/>.
28188 <literal>current_setting('datestyle')
</literal>
28189 <returnvalue>ISO, MDY
</returnvalue>
28194 <entry role=
"func_table_entry"><para role=
"func_signature">
28196 <primary>set_config
</primary>
28198 <function>set_config
</function> (
28199 <parameter>setting_name
</parameter> <type>text
</type>,
28200 <parameter>new_value
</parameter> <type>text
</type>,
28201 <parameter>is_local
</parameter> <type>boolean
</type> )
28202 <returnvalue>text
</returnvalue>
28205 Sets the parameter
<parameter>setting_name
</parameter>
28206 to
<parameter>new_value
</parameter>, and returns that value.
28207 If
<parameter>is_local
</parameter> is
<literal>true
</literal>, the new
28208 value will only apply during the current transaction. If you want the
28209 new value to apply for the rest of the current session,
28210 use
<literal>false
</literal> instead. This function corresponds to
28211 the SQL command
<xref linkend=
"sql-set"/>.
28214 <literal>set_config('log_statement_stats', 'off', false)
</literal>
28215 <returnvalue>off
</returnvalue>
28224 <sect2 id=
"functions-admin-signal">
28225 <title>Server Signaling Functions
</title>
28228 <primary>signal
</primary>
28229 <secondary sortas=
"backend">backend processes
</secondary>
28233 The functions shown in
<xref
28234 linkend=
"functions-admin-signal-table"/> send control signals to
28235 other server processes. Use of these functions is restricted to
28236 superusers by default but access may be granted to others using
28237 <command>GRANT
</command>, with noted exceptions.
28241 Each of these functions returns
<literal>true
</literal> if
28242 the signal was successfully sent and
<literal>false
</literal>
28243 if sending the signal failed.
28246 <table id=
"functions-admin-signal-table">
28247 <title>Server Signaling Functions
</title>
28251 <entry role=
"func_table_entry"><para role=
"func_signature">
28262 <entry role=
"func_table_entry"><para role=
"func_signature">
28264 <primary>pg_cancel_backend
</primary>
28266 <function>pg_cancel_backend
</function> (
<parameter>pid
</parameter> <type>integer
</type> )
28267 <returnvalue>boolean
</returnvalue>
28270 Cancels the current query of the session whose backend process has the
28271 specified process ID. This is also allowed if the
28272 calling role is a member of the role whose backend is being canceled or
28273 the calling role has privileges of
<literal>pg_signal_backend
</literal>,
28274 however only superusers can cancel superuser backends.
28275 As an exception, roles with privileges of
28276 <literal>pg_signal_autovacuum_worker
</literal> are permitted to
28277 cancel autovacuum worker processes, which are otherwise considered
28278 superuser backends.
28283 <entry role=
"func_table_entry"><para role=
"func_signature">
28285 <primary>pg_log_backend_memory_contexts
</primary>
28287 <function>pg_log_backend_memory_contexts
</function> (
<parameter>pid
</parameter> <type>integer
</type> )
28288 <returnvalue>boolean
</returnvalue>
28291 Requests to log the memory contexts of the backend with the
28292 specified process ID. This function can send the request to
28293 backends and auxiliary processes except logger. These memory contexts
28295 <literal>LOG
</literal> message level. They will appear in
28296 the server log based on the log configuration set
28297 (see
<xref linkend=
"runtime-config-logging"/> for more information),
28298 but will not be sent to the client regardless of
28299 <xref linkend=
"guc-client-min-messages"/>.
28304 <entry role=
"func_table_entry"><para role=
"func_signature">
28306 <primary>pg_reload_conf
</primary>
28308 <function>pg_reload_conf
</function> ()
28309 <returnvalue>boolean
</returnvalue>
28312 Causes all processes of the
<productname>PostgreSQL
</productname>
28313 server to reload their configuration files. (This is initiated by
28314 sending a
<systemitem>SIGHUP
</systemitem> signal to the postmaster
28315 process, which in turn sends
<systemitem>SIGHUP
</systemitem> to each
28316 of its children.) You can use the
28317 <link linkend=
"view-pg-file-settings"><structname>pg_file_settings
</structname></link>,
28318 <link linkend=
"view-pg-hba-file-rules"><structname>pg_hba_file_rules
</structname></link> and
28319 <link linkend=
"view-pg-ident-file-mappings"><structname>pg_ident_file_mappings
</structname></link> views
28320 to check the configuration files for possible errors, before reloading.
28325 <entry role=
"func_table_entry"><para role=
"func_signature">
28327 <primary>pg_rotate_logfile
</primary>
28329 <function>pg_rotate_logfile
</function> ()
28330 <returnvalue>boolean
</returnvalue>
28333 Signals the log-file manager to switch to a new output file
28334 immediately. This works only when the built-in log collector is
28335 running, since otherwise there is no log-file manager subprocess.
28340 <entry role=
"func_table_entry"><para role=
"func_signature">
28342 <primary>pg_terminate_backend
</primary>
28344 <function>pg_terminate_backend
</function> (
<parameter>pid
</parameter> <type>integer
</type>,
<parameter>timeout
</parameter> <type>bigint
</type> <literal>DEFAULT
</literal> <literal>0</literal> )
28345 <returnvalue>boolean
</returnvalue>
28348 Terminates the session whose backend process has the
28349 specified process ID. This is also allowed if the calling role
28350 is a member of the role whose backend is being terminated or the
28351 calling role has privileges of
<literal>pg_signal_backend
</literal>,
28352 however only superusers can terminate superuser backends.
28353 As an exception, roles with privileges of
28354 <literal>pg_signal_autovacuum_worker
</literal> are permitted to
28355 terminate autovacuum worker processes, which are otherwise considered
28356 superuser backends.
28359 If
<parameter>timeout
</parameter> is not specified or zero, this
28360 function returns
<literal>true
</literal> whether the process actually
28361 terminates or not, indicating only that the sending of the signal was
28362 successful. If the
<parameter>timeout
</parameter> is specified (in
28363 milliseconds) and greater than zero, the function waits until the
28364 process is actually terminated or until the given time has passed. If
28365 the process is terminated, the function
28366 returns
<literal>true
</literal>. On timeout, a warning is emitted and
28367 <literal>false
</literal> is returned.
28375 <function>pg_cancel_backend
</function> and
<function>pg_terminate_backend
</function>
28376 send signals (
<systemitem>SIGINT
</systemitem> or
<systemitem>SIGTERM
</systemitem>
28377 respectively) to backend processes identified by process ID.
28378 The process ID of an active backend can be found from
28379 the
<structfield>pid
</structfield> column of the
28380 <structname>pg_stat_activity
</structname> view, or by listing the
28381 <command>postgres
</command> processes on the server (using
28382 <application>ps
</application> on Unix or the
<application>Task
28383 Manager
</application> on
<productname>Windows
</productname>).
28384 The role of an active backend can be found from the
28385 <structfield>usename
</structfield> column of the
28386 <structname>pg_stat_activity
</structname> view.
28390 <function>pg_log_backend_memory_contexts
</function> can be used
28391 to log the memory contexts of a backend process. For example:
28393 postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid());
28394 pg_log_backend_memory_contexts
28395 --------------------------------
28399 One message for each memory context will be logged. For example:
28401 LOG: logging memory contexts of PID
10377
28402 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid());
28403 LOG: level:
0; TopMemoryContext:
80800 total in
6 blocks;
14432 free (
5 chunks);
66368 used
28404 LOG: level:
1; pgstat TabStatusArray lookup hash table:
8192 total in
1 blocks;
1408 free (
0 chunks);
6784 used
28405 LOG: level:
1; TopTransactionContext:
8192 total in
1 blocks;
7720 free (
1 chunks);
472 used
28406 LOG: level:
1; RowDescriptionContext:
8192 total in
1 blocks;
6880 free (
0 chunks);
1312 used
28407 LOG: level:
1; MessageContext:
16384 total in
2 blocks;
5152 free (
0 chunks);
11232 used
28408 LOG: level:
1; Operator class cache:
8192 total in
1 blocks;
512 free (
0 chunks);
7680 used
28409 LOG: level:
1; smgr relation table:
16384 total in
2 blocks;
4544 free (
3 chunks);
11840 used
28410 LOG: level:
1; TransactionAbortContext:
32768 total in
1 blocks;
32504 free (
0 chunks);
264 used
28412 LOG: level:
1; ErrorContext:
8192 total in
1 blocks;
7928 free (
3 chunks);
264 used
28413 LOG: Grand total:
1651920 bytes in
201 blocks;
622360 free (
88 chunks);
1029560 used
28415 If there are more than
100 child contexts under the same parent, the first
28416 100 child contexts are logged, along with a summary of the remaining contexts.
28417 Note that frequent calls to this function could incur significant overhead,
28418 because it may generate a large number of log messages.
28423 <sect2 id=
"functions-admin-backup">
28424 <title>Backup Control Functions
</title>
28427 <primary>backup
</primary>
28431 The functions shown in
<xref
28432 linkend=
"functions-admin-backup-table"/> assist in making on-line backups.
28433 These functions cannot be executed during recovery (except
28434 <function>pg_backup_start
</function>,
28435 <function>pg_backup_stop
</function>,
28436 and
<function>pg_wal_lsn_diff
</function>).
28440 For details about proper usage of these functions, see
28441 <xref linkend=
"continuous-archiving"/>.
28444 <table id=
"functions-admin-backup-table">
28445 <title>Backup Control Functions
</title>
28449 <entry role=
"func_table_entry"><para role=
"func_signature">
28460 <entry role=
"func_table_entry"><para role=
"func_signature">
28462 <primary>pg_create_restore_point
</primary>
28464 <function>pg_create_restore_point
</function> (
<parameter>name
</parameter> <type>text
</type> )
28465 <returnvalue>pg_lsn
</returnvalue>
28468 Creates a named marker record in the write-ahead log that can later be
28469 used as a recovery target, and returns the corresponding write-ahead
28470 log location. The given name can then be used with
28471 <xref linkend=
"guc-recovery-target-name"/> to specify the point up to
28472 which recovery will proceed. Avoid creating multiple restore points
28473 with the same name, since recovery will stop at the first one whose
28474 name matches the recovery target.
28477 This function is restricted to superusers by default, but other users
28478 can be granted EXECUTE to run the function.
28483 <entry role=
"func_table_entry"><para role=
"func_signature">
28485 <primary>pg_current_wal_flush_lsn
</primary>
28487 <function>pg_current_wal_flush_lsn
</function> ()
28488 <returnvalue>pg_lsn
</returnvalue>
28491 Returns the current write-ahead log flush location (see notes below).
28496 <entry role=
"func_table_entry"><para role=
"func_signature">
28498 <primary>pg_current_wal_insert_lsn
</primary>
28500 <function>pg_current_wal_insert_lsn
</function> ()
28501 <returnvalue>pg_lsn
</returnvalue>
28504 Returns the current write-ahead log insert location (see notes below).
28509 <entry role=
"func_table_entry"><para role=
"func_signature">
28511 <primary>pg_current_wal_lsn
</primary>
28513 <function>pg_current_wal_lsn
</function> ()
28514 <returnvalue>pg_lsn
</returnvalue>
28517 Returns the current write-ahead log write location (see notes below).
28522 <entry role=
"func_table_entry"><para role=
"func_signature">
28524 <primary>pg_backup_start
</primary>
28526 <function>pg_backup_start
</function> (
28527 <parameter>label
</parameter> <type>text
</type>
28528 <optional>,
<parameter>fast
</parameter> <type>boolean
</type>
28530 <returnvalue>pg_lsn
</returnvalue>
28533 Prepares the server to begin an on-line backup. The only required
28534 parameter is an arbitrary user-defined label for the backup.
28535 (Typically this would be the name under which the backup dump file
28537 If the optional second parameter is given as
<literal>true
</literal>,
28538 it specifies executing
<function>pg_backup_start
</function> as quickly
28539 as possible. This forces an immediate checkpoint which will cause a
28540 spike in I/O operations, slowing any concurrently executing queries.
28543 This function is restricted to superusers by default, but other users
28544 can be granted EXECUTE to run the function.
28549 <entry role=
"func_table_entry"><para role=
"func_signature">
28551 <primary>pg_backup_stop
</primary>
28553 <function>pg_backup_stop
</function> (
28554 <optional><parameter>wait_for_archive
</parameter> <type>boolean
</type>
28556 <returnvalue>record
</returnvalue>
28557 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
28558 <parameter>labelfile
</parameter> <type>text
</type>,
28559 <parameter>spcmapfile
</parameter> <type>text
</type> )
28562 Finishes performing an on-line backup. The desired contents of the
28563 backup label file and the tablespace map file are returned as part of
28564 the result of the function and must be written to files in the
28565 backup area. These files must not be written to the live data directory
28566 (doing so will cause PostgreSQL to fail to restart in the event of a
28570 There is an optional parameter of type
<type>boolean
</type>.
28571 If false, the function will return immediately after the backup is
28572 completed, without waiting for WAL to be archived. This behavior is
28573 only useful with backup software that independently monitors WAL
28574 archiving. Otherwise, WAL required to make the backup consistent might
28575 be missing and make the backup useless. By default or when this
28576 parameter is true,
<function>pg_backup_stop
</function> will wait for
28577 WAL to be archived when archiving is enabled. (On a standby, this
28578 means that it will wait only when
<varname>archive_mode
</varname> =
28579 <literal>always
</literal>. If write activity on the primary is low,
28580 it may be useful to run
<function>pg_switch_wal
</function> on the
28581 primary in order to trigger an immediate segment switch.)
28584 When executed on a primary, this function also creates a backup
28585 history file in the write-ahead log archive area. The history file
28586 includes the label given to
<function>pg_backup_start
</function>, the
28587 starting and ending write-ahead log locations for the backup, and the
28588 starting and ending times of the backup. After recording the ending
28589 location, the current write-ahead log insertion point is automatically
28590 advanced to the next write-ahead log file, so that the ending
28591 write-ahead log file can be archived immediately to complete the
28595 The result of the function is a single record.
28596 The
<parameter>lsn
</parameter> column holds the backup's ending
28597 write-ahead log location (which again can be ignored). The second
28598 column returns the contents of the backup label file, and the third
28599 column returns the contents of the tablespace map file. These must be
28600 stored as part of the backup and are required as part of the restore
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_switch_wal
</primary>
28614 <function>pg_switch_wal
</function> ()
28615 <returnvalue>pg_lsn
</returnvalue>
28618 Forces the server to switch to a new write-ahead log file, which
28619 allows the current file to be archived (assuming you are using
28620 continuous archiving). The result is the ending write-ahead log
28621 location plus
1 within the just-completed write-ahead log file. If
28622 there has been no write-ahead log activity since the last write-ahead
28623 log switch,
<function>pg_switch_wal
</function> does nothing and
28624 returns the start location of the write-ahead log file currently in
28628 This function is restricted to superusers by default, but other users
28629 can be granted EXECUTE to run the function.
28634 <entry role=
"func_table_entry"><para role=
"func_signature">
28636 <primary>pg_walfile_name
</primary>
28638 <function>pg_walfile_name
</function> (
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
28639 <returnvalue>text
</returnvalue>
28642 Converts a write-ahead log location to the name of the WAL file
28643 holding that location.
28648 <entry role=
"func_table_entry"><para role=
"func_signature">
28650 <primary>pg_walfile_name_offset
</primary>
28652 <function>pg_walfile_name_offset
</function> (
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
28653 <returnvalue>record
</returnvalue>
28654 (
<parameter>file_name
</parameter> <type>text
</type>,
28655 <parameter>file_offset
</parameter> <type>integer
</type> )
28658 Converts a write-ahead log location to a WAL file name and byte offset
28664 <entry role=
"func_table_entry"><para role=
"func_signature">
28666 <primary>pg_split_walfile_name
</primary>
28668 <function>pg_split_walfile_name
</function> (
<parameter>file_name
</parameter> <type>text
</type> )
28669 <returnvalue>record
</returnvalue>
28670 (
<parameter>segment_number
</parameter> <type>numeric
</type>,
28671 <parameter>timeline_id
</parameter> <type>bigint
</type> )
28674 Extracts the sequence number and timeline ID from a WAL file
28680 <entry role=
"func_table_entry"><para role=
"func_signature">
28682 <primary>pg_wal_lsn_diff
</primary>
28684 <function>pg_wal_lsn_diff
</function> (
<parameter>lsn1
</parameter> <type>pg_lsn
</type>,
<parameter>lsn2
</parameter> <type>pg_lsn
</type> )
28685 <returnvalue>numeric
</returnvalue>
28688 Calculates the difference in bytes (
<parameter>lsn1
</parameter> -
<parameter>lsn2
</parameter>) between two write-ahead log
28689 locations. This can be used
28690 with
<structname>pg_stat_replication
</structname> or some of the
28691 functions shown in
<xref linkend=
"functions-admin-backup-table"/> to
28692 get the replication lag.
28700 <function>pg_current_wal_lsn
</function> displays the current write-ahead
28701 log write location in the same format used by the above functions.
28702 Similarly,
<function>pg_current_wal_insert_lsn
</function> displays the
28703 current write-ahead log insertion location
28704 and
<function>pg_current_wal_flush_lsn
</function> displays the current
28705 write-ahead log flush location. The insertion location is
28706 the
<quote>logical
</quote> end of the write-ahead log at any instant,
28707 while the write location is the end of what has actually been written out
28708 from the server's internal buffers, and the flush location is the last
28709 location known to be written to durable storage. The write location is the
28710 end of what can be examined from outside the server, and is usually what
28711 you want if you are interested in archiving partially-complete write-ahead
28712 log files. The insertion and flush locations are made available primarily
28713 for server debugging purposes. These are all read-only operations and do
28714 not require superuser permissions.
28718 You can use
<function>pg_walfile_name_offset
</function> to extract the
28719 corresponding write-ahead log file name and byte offset from
28720 a
<type>pg_lsn
</type> value. For example:
28722 postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn);
28723 file_name | file_offset
28724 --------------------------+-------------
28725 00000001000000000000000D |
4039624
28728 Similarly,
<function>pg_walfile_name
</function> extracts just the write-ahead log file name.
28732 <function>pg_split_walfile_name
</function> is useful to compute a
28733 <acronym>LSN
</acronym> from a file offset and WAL file name, for example:
28735 postgres=# \set file_name '
000000010000000100C000AB'
28736 postgres=# \set offset
256
28737 postgres=# SELECT '
0/
0'::pg_lsn + pd.segment_number * ps.setting::int + :offset AS lsn
28738 FROM pg_split_walfile_name(:'file_name') pd,
28739 pg_show_all_settings() ps
28740 WHERE ps.name = 'wal_segment_size';
28750 <sect2 id=
"functions-recovery-control">
28751 <title>Recovery Control Functions
</title>
28754 The functions shown in
<xref
28755 linkend=
"functions-recovery-info-table"/> provide information
28756 about the current status of a standby server.
28757 These functions may be executed both during recovery and in normal running.
28760 <table id=
"functions-recovery-info-table">
28761 <title>Recovery Information Functions
</title>
28765 <entry role=
"func_table_entry"><para role=
"func_signature">
28776 <entry role=
"func_table_entry"><para role=
"func_signature">
28778 <primary>pg_is_in_recovery
</primary>
28780 <function>pg_is_in_recovery
</function> ()
28781 <returnvalue>boolean
</returnvalue>
28784 Returns true if recovery is still in progress.
28789 <entry role=
"func_table_entry"><para role=
"func_signature">
28791 <primary>pg_last_wal_receive_lsn
</primary>
28793 <function>pg_last_wal_receive_lsn
</function> ()
28794 <returnvalue>pg_lsn
</returnvalue>
28797 Returns the last write-ahead log location that has been received and
28798 synced to disk by streaming replication. While streaming replication
28799 is in progress this will increase monotonically. If recovery has
28800 completed then this will remain static at the location of the last WAL
28801 record received and synced to disk during recovery. If streaming
28802 replication is disabled, or if it has not yet started, the function
28803 returns
<literal>NULL
</literal>.
28808 <entry role=
"func_table_entry"><para role=
"func_signature">
28810 <primary>pg_last_wal_replay_lsn
</primary>
28812 <function>pg_last_wal_replay_lsn
</function> ()
28813 <returnvalue>pg_lsn
</returnvalue>
28816 Returns the last write-ahead log location that has been replayed
28817 during recovery. If recovery is still in progress this will increase
28818 monotonically. If recovery has completed then this will remain
28819 static at the location of the last WAL record applied during recovery.
28820 When the server has been started normally without recovery, the
28821 function returns
<literal>NULL
</literal>.
28826 <entry role=
"func_table_entry"><para role=
"func_signature">
28828 <primary>pg_last_xact_replay_timestamp
</primary>
28830 <function>pg_last_xact_replay_timestamp
</function> ()
28831 <returnvalue>timestamp with time zone
</returnvalue>
28834 Returns the time stamp of the last transaction replayed during
28835 recovery. This is the time at which the commit or abort WAL record
28836 for that transaction was generated on the primary. If no transactions
28837 have been replayed during recovery, the function
28838 returns
<literal>NULL
</literal>. Otherwise, if recovery is still in
28839 progress this will increase monotonically. If recovery has completed
28840 then this will remain static at the time of the last transaction
28841 applied during recovery. When the server has been started normally
28842 without recovery, the function returns
<literal>NULL
</literal>.
28847 <entry role=
"func_table_entry"><para role=
"func_signature">
28849 <primary>pg_get_wal_resource_managers
</primary>
28851 <function>pg_get_wal_resource_managers
</function> ()
28852 <returnvalue>setof record
</returnvalue>
28853 (
<parameter>rm_id
</parameter> <type>integer
</type>,
28854 <parameter>rm_name
</parameter> <type>text
</type>,
28855 <parameter>rm_builtin
</parameter> <type>boolean
</type> )
28858 Returns the currently-loaded WAL resource managers in the system. The
28859 column
<parameter>rm_builtin
</parameter> indicates whether it's a
28860 built-in resource manager, or a custom resource manager loaded by an
28869 The functions shown in
<xref
28870 linkend=
"functions-recovery-control-table"/> control the progress of recovery.
28871 These functions may be executed only during recovery.
28874 <table id=
"functions-recovery-control-table">
28875 <title>Recovery Control Functions
</title>
28879 <entry role=
"func_table_entry"><para role=
"func_signature">
28890 <entry role=
"func_table_entry"><para role=
"func_signature">
28892 <primary>pg_is_wal_replay_paused
</primary>
28894 <function>pg_is_wal_replay_paused
</function> ()
28895 <returnvalue>boolean
</returnvalue>
28898 Returns true if recovery pause is requested.
28903 <entry role=
"func_table_entry"><para role=
"func_signature">
28905 <primary>pg_get_wal_replay_pause_state
</primary>
28907 <function>pg_get_wal_replay_pause_state
</function> ()
28908 <returnvalue>text
</returnvalue>
28911 Returns recovery pause state. The return values are
<literal>
28912 not paused
</literal> if pause is not requested,
<literal>
28913 pause requested
</literal> if pause is requested but recovery is
28914 not yet paused, and
<literal>paused
</literal> if the recovery is
28920 <entry role=
"func_table_entry"><para role=
"func_signature">
28922 <primary>pg_promote
</primary>
28924 <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> )
28925 <returnvalue>boolean
</returnvalue>
28928 Promotes a standby server to primary status.
28929 With
<parameter>wait
</parameter> set to
<literal>true
</literal> (the
28930 default), the function waits until promotion is completed
28931 or
<parameter>wait_seconds
</parameter> seconds have passed, and
28932 returns
<literal>true
</literal> if promotion is successful
28933 and
<literal>false
</literal> otherwise.
28934 If
<parameter>wait
</parameter> is set to
<literal>false
</literal>, the
28935 function returns
<literal>true
</literal> immediately after sending a
28936 <literal>SIGUSR1
</literal> signal to the postmaster to trigger
28940 This function is restricted to superusers by default, but other users
28941 can be granted EXECUTE to run the function.
28946 <entry role=
"func_table_entry"><para role=
"func_signature">
28948 <primary>pg_wal_replay_pause
</primary>
28950 <function>pg_wal_replay_pause
</function> ()
28951 <returnvalue>void
</returnvalue>
28954 Request to pause recovery. A request doesn't mean that recovery stops
28955 right away. If you want a guarantee that recovery is actually paused,
28956 you need to check for the recovery pause state returned by
28957 <function>pg_get_wal_replay_pause_state()
</function>. Note that
28958 <function>pg_is_wal_replay_paused()
</function> returns whether a request
28959 is made. While recovery is paused, no further database changes are applied.
28960 If hot standby is active, all new queries will see the same consistent
28961 snapshot of the database, and no further query conflicts will be generated
28962 until recovery is resumed.
28965 This function is restricted to superusers by default, but other users
28966 can be granted EXECUTE to run the function.
28971 <entry role=
"func_table_entry"><para role=
"func_signature">
28973 <primary>pg_wal_replay_resume
</primary>
28975 <function>pg_wal_replay_resume
</function> ()
28976 <returnvalue>void
</returnvalue>
28979 Restarts recovery if it was paused.
28982 This function is restricted to superusers by default, but other users
28983 can be granted EXECUTE to run the function.
28991 <function>pg_wal_replay_pause
</function> and
28992 <function>pg_wal_replay_resume
</function> cannot be executed while
28993 a promotion is ongoing. If a promotion is triggered while recovery
28994 is paused, the paused state ends and promotion continues.
28998 If streaming replication is disabled, the paused state may continue
28999 indefinitely without a problem. If streaming replication is in
29000 progress then WAL records will continue to be received, which will
29001 eventually fill available disk space, depending upon the duration of
29002 the pause, the rate of WAL generation and available disk space.
29007 <sect2 id=
"functions-snapshot-synchronization">
29008 <title>Snapshot Synchronization Functions
</title>
29011 <productname>PostgreSQL
</productname> allows database sessions to synchronize their
29012 snapshots. A
<firstterm>snapshot
</firstterm> determines which data is visible to the
29013 transaction that is using the snapshot. Synchronized snapshots are
29014 necessary when two or more sessions need to see identical content in the
29015 database. If two sessions just start their transactions independently,
29016 there is always a possibility that some third transaction commits
29017 between the executions of the two
<command>START TRANSACTION
</command> commands,
29018 so that one session sees the effects of that transaction and the other
29023 To solve this problem,
<productname>PostgreSQL
</productname> allows a transaction to
29024 <firstterm>export
</firstterm> the snapshot it is using. As long as the exporting
29025 transaction remains open, other transactions can
<firstterm>import
</firstterm> its
29026 snapshot, and thereby be guaranteed that they see exactly the same view
29027 of the database that the first transaction sees. But note that any
29028 database changes made by any one of these transactions remain invisible
29029 to the other transactions, as is usual for changes made by uncommitted
29030 transactions. So the transactions are synchronized with respect to
29031 pre-existing data, but act normally for changes they make themselves.
29035 Snapshots are exported with the
<function>pg_export_snapshot
</function> function,
29036 shown in
<xref linkend=
"functions-snapshot-synchronization-table"/>, and
29037 imported with the
<xref linkend=
"sql-set-transaction"/> command.
29040 <table id=
"functions-snapshot-synchronization-table">
29041 <title>Snapshot Synchronization Functions
</title>
29045 <entry role=
"func_table_entry"><para role=
"func_signature">
29056 <entry role=
"func_table_entry"><para role=
"func_signature">
29058 <primary>pg_export_snapshot
</primary>
29060 <function>pg_export_snapshot
</function> ()
29061 <returnvalue>text
</returnvalue>
29064 Saves the transaction's current snapshot and returns
29065 a
<type>text
</type> string identifying the snapshot. This string must
29066 be passed (outside the database) to clients that want to import the
29067 snapshot. The snapshot is available for import only until the end of
29068 the transaction that exported it.
29071 A transaction can export more than one snapshot, if needed. Note that
29072 doing so is only useful in
<literal>READ COMMITTED
</literal>
29073 transactions, since in
<literal>REPEATABLE READ
</literal> and higher
29074 isolation levels, transactions use the same snapshot throughout their
29075 lifetime. Once a transaction has exported any snapshots, it cannot be
29076 prepared with
<xref linkend=
"sql-prepare-transaction"/>.
29080 <entry role=
"func_table_entry"><para role=
"func_signature">
29082 <primary>pg_log_standby_snapshot
</primary>
29084 <function>pg_log_standby_snapshot
</function> ()
29085 <returnvalue>pg_lsn
</returnvalue>
29088 Take a snapshot of running transactions and write it to WAL, without
29089 having to wait for bgwriter or checkpointer to log one. This is useful
29090 for logical decoding on standby, as logical slot creation has to wait
29091 until such a record is replayed on the standby.
29100 <sect2 id=
"functions-replication">
29101 <title>Replication Management Functions
</title>
29104 The functions shown
29105 in
<xref linkend=
"functions-replication-table"/> are for
29106 controlling and interacting with replication features.
29107 See
<xref linkend=
"streaming-replication"/>,
29108 <xref linkend=
"streaming-replication-slots"/>, and
29109 <xref linkend=
"replication-origins"/>
29110 for information about the underlying features.
29111 Use of functions for replication origin is only allowed to the
29112 superuser by default, but may be allowed to other users by using the
29113 <literal>GRANT
</literal> command.
29114 Use of functions for replication slots is restricted to superusers
29115 and users having
<literal>REPLICATION
</literal> privilege.
29119 Many of these functions have equivalent commands in the replication
29120 protocol; see
<xref linkend=
"protocol-replication"/>.
29124 The functions described in
29125 <xref linkend=
"functions-admin-backup"/>,
29126 <xref linkend=
"functions-recovery-control"/>, and
29127 <xref linkend=
"functions-snapshot-synchronization"/>
29128 are also relevant for replication.
29131 <table id=
"functions-replication-table">
29132 <title>Replication Management Functions
</title>
29136 <entry role=
"func_table_entry"><para role=
"func_signature">
29147 <entry role=
"func_table_entry"><para role=
"func_signature">
29149 <primary>pg_create_physical_replication_slot
</primary>
29151 <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> )
29152 <returnvalue>record
</returnvalue>
29153 (
<parameter>slot_name
</parameter> <type>name
</type>,
29154 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29157 Creates a new physical replication slot named
29158 <parameter>slot_name
</parameter>. The optional second parameter,
29159 when
<literal>true
</literal>, specifies that the
<acronym>LSN
</acronym> for this
29160 replication slot be reserved immediately; otherwise
29161 the
<acronym>LSN
</acronym> is reserved on first connection from a streaming
29162 replication client. Streaming changes from a physical slot is only
29163 possible with the streaming-replication protocol
—
29164 see
<xref linkend=
"protocol-replication"/>. The optional third
29165 parameter,
<parameter>temporary
</parameter>, when set to true, specifies that
29166 the slot should not be permanently stored to disk and is only meant
29167 for use by the current session. Temporary slots are also
29168 released upon any error. This function corresponds
29169 to the replication protocol command
<literal>CREATE_REPLICATION_SLOT
29170 ... PHYSICAL
</literal>.
29175 <entry role=
"func_table_entry"><para role=
"func_signature">
29177 <primary>pg_drop_replication_slot
</primary>
29179 <function>pg_drop_replication_slot
</function> (
<parameter>slot_name
</parameter> <type>name
</type> )
29180 <returnvalue>void
</returnvalue>
29183 Drops the physical or logical replication slot
29184 named
<parameter>slot_name
</parameter>. Same as replication protocol
29185 command
<literal>DROP_REPLICATION_SLOT
</literal>. For logical slots, this must
29186 be called while connected to the same database the slot was created on.
29191 <entry id=
"pg-create-logical-replication-slot" role=
"func_table_entry"><para role=
"func_signature">
29193 <primary>pg_create_logical_replication_slot
</primary>
29195 <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> )
29196 <returnvalue>record
</returnvalue>
29197 (
<parameter>slot_name
</parameter> <type>name
</type>,
29198 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29201 Creates a new logical (decoding) replication slot named
29202 <parameter>slot_name
</parameter> using the output plugin
29203 <parameter>plugin
</parameter>. The optional third
29204 parameter,
<parameter>temporary
</parameter>, when set to true, specifies that
29205 the slot should not be permanently stored to disk and is only meant
29206 for use by the current session. Temporary slots are also
29207 released upon any error. The optional fourth parameter,
29208 <parameter>twophase
</parameter>, when set to true, specifies
29209 that the decoding of prepared transactions is enabled for this
29210 slot. The optional fifth parameter,
29211 <parameter>failover
</parameter>, when set to true,
29212 specifies that this slot is enabled to be synced to the
29213 standbys so that logical replication can be resumed after
29214 failover. A call to this function has the same effect as
29215 the replication protocol command
29216 <literal>CREATE_REPLICATION_SLOT ... LOGICAL
</literal>.
29221 <entry role=
"func_table_entry"><para role=
"func_signature">
29223 <primary>pg_copy_physical_replication_slot
</primary>
29225 <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> )
29226 <returnvalue>record
</returnvalue>
29227 (
<parameter>slot_name
</parameter> <type>name
</type>,
29228 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29231 Copies an existing physical replication slot named
<parameter>src_slot_name
</parameter>
29232 to a physical replication slot named
<parameter>dst_slot_name
</parameter>.
29233 The copied physical slot starts to reserve WAL from the same
<acronym>LSN
</acronym> as the
29235 <parameter>temporary
</parameter> is optional. If
<parameter>temporary
</parameter>
29236 is omitted, the same value as the source slot is used.
29241 <entry role=
"func_table_entry"><para role=
"func_signature">
29243 <primary>pg_copy_logical_replication_slot
</primary>
29245 <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> )
29246 <returnvalue>record
</returnvalue>
29247 (
<parameter>slot_name
</parameter> <type>name
</type>,
29248 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
29251 Copies an existing logical replication slot
29252 named
<parameter>src_slot_name
</parameter> to a logical replication
29253 slot named
<parameter>dst_slot_name
</parameter>, optionally changing
29254 the output plugin and persistence. The copied logical slot starts
29255 from the same
<acronym>LSN
</acronym> as the source logical slot. Both
29256 <parameter>temporary
</parameter> and
<parameter>plugin
</parameter> are
29257 optional; if they are omitted, the values of the source slot are used.
29262 <entry id=
"pg-logical-slot-get-changes" role=
"func_table_entry"><para role=
"func_signature">
29264 <primary>pg_logical_slot_get_changes
</primary>
29266 <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> )
29267 <returnvalue>setof record
</returnvalue>
29268 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29269 <parameter>xid
</parameter> <type>xid
</type>,
29270 <parameter>data
</parameter> <type>text
</type> )
29273 Returns changes in the slot
<parameter>slot_name
</parameter>, starting
29274 from the point from which changes have been consumed last. If
29275 <parameter>upto_lsn
</parameter>
29276 and
<parameter>upto_nchanges
</parameter> are NULL,
29277 logical decoding will continue until end of WAL. If
29278 <parameter>upto_lsn
</parameter> is non-NULL, decoding will include only
29279 those transactions which commit prior to the specified LSN. If
29280 <parameter>upto_nchanges
</parameter> is non-NULL, decoding will
29281 stop when the number of rows produced by decoding exceeds
29282 the specified value. Note, however, that the actual number of
29283 rows returned may be larger, since this limit is only checked after
29284 adding the rows produced when decoding each new transaction commit.
29285 If the specified slot is a logical failover slot then the function will
29286 not return until all physical slots specified in
29287 <link linkend=
"guc-synchronized-standby-slots"><varname>synchronized_standby_slots
</varname></link>
29288 have confirmed WAL receipt.
29293 <entry id=
"pg-logical-slot-peek-changes" role=
"func_table_entry"><para role=
"func_signature">
29295 <primary>pg_logical_slot_peek_changes
</primary>
29297 <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> )
29298 <returnvalue>setof record
</returnvalue>
29299 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29300 <parameter>xid
</parameter> <type>xid
</type>,
29301 <parameter>data
</parameter> <type>text
</type> )
29305 the
<function>pg_logical_slot_get_changes()
</function> function,
29306 except that changes are not consumed; that is, they will be returned
29307 again on future calls.
29312 <entry role=
"func_table_entry"><para role=
"func_signature">
29314 <primary>pg_logical_slot_get_binary_changes
</primary>
29316 <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> )
29317 <returnvalue>setof record
</returnvalue>
29318 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29319 <parameter>xid
</parameter> <type>xid
</type>,
29320 <parameter>data
</parameter> <type>bytea
</type> )
29324 the
<function>pg_logical_slot_get_changes()
</function> function,
29325 except that changes are returned as
<type>bytea
</type>.
29330 <entry role=
"func_table_entry"><para role=
"func_signature">
29332 <primary>pg_logical_slot_peek_binary_changes
</primary>
29334 <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> )
29335 <returnvalue>setof record
</returnvalue>
29336 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
29337 <parameter>xid
</parameter> <type>xid
</type>,
29338 <parameter>data
</parameter> <type>bytea
</type> )
29342 the
<function>pg_logical_slot_peek_changes()
</function> function,
29343 except that changes are returned as
<type>bytea
</type>.
29348 <entry id=
"pg-replication-slot-advance" role=
"func_table_entry"><para role=
"func_signature">
29350 <primary>pg_replication_slot_advance
</primary>
29352 <function>pg_replication_slot_advance
</function> (
<parameter>slot_name
</parameter> <type>name
</type>,
<parameter>upto_lsn
</parameter> <type>pg_lsn
</type> )
29353 <returnvalue>record
</returnvalue>
29354 (
<parameter>slot_name
</parameter> <type>name
</type>,
29355 <parameter>end_lsn
</parameter> <type>pg_lsn
</type> )
29358 Advances the current confirmed position of a replication slot named
29359 <parameter>slot_name
</parameter>. The slot will not be moved backwards,
29360 and it will not be moved beyond the current insert location. Returns
29361 the name of the slot and the actual position that it was advanced to.
29362 The updated slot position information is written out at the next
29363 checkpoint if any advancing is done. So in the event of a crash, the
29364 slot may return to an earlier position. If the specified slot is a
29365 logical failover slot then the function will not return until all
29366 physical slots specified in
29367 <link linkend=
"guc-synchronized-standby-slots"><varname>synchronized_standby_slots
</varname></link>
29368 have confirmed WAL receipt.
29373 <entry id=
"pg-replication-origin-create" role=
"func_table_entry"><para role=
"func_signature">
29375 <primary>pg_replication_origin_create
</primary>
29377 <function>pg_replication_origin_create
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29378 <returnvalue>oid
</returnvalue>
29381 Creates a replication origin with the given external
29382 name, and returns the internal ID assigned to it.
29387 <entry id=
"pg-replication-origin-drop" role=
"func_table_entry"><para role=
"func_signature">
29389 <primary>pg_replication_origin_drop
</primary>
29391 <function>pg_replication_origin_drop
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29392 <returnvalue>void
</returnvalue>
29395 Deletes a previously-created replication origin, including any
29396 associated replay progress.
29401 <entry role=
"func_table_entry"><para role=
"func_signature">
29403 <primary>pg_replication_origin_oid
</primary>
29405 <function>pg_replication_origin_oid
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29406 <returnvalue>oid
</returnvalue>
29409 Looks up a replication origin by name and returns the internal ID. If
29410 no such replication origin is found,
<literal>NULL
</literal> is
29416 <entry id=
"pg-replication-origin-session-setup" role=
"func_table_entry"><para role=
"func_signature">
29418 <primary>pg_replication_origin_session_setup
</primary>
29420 <function>pg_replication_origin_session_setup
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
29421 <returnvalue>void
</returnvalue>
29424 Marks the current session as replaying from the given
29425 origin, allowing replay progress to be tracked.
29426 Can only be used if no origin is currently selected.
29427 Use
<function>pg_replication_origin_session_reset
</function> to undo.
29432 <entry role=
"func_table_entry"><para role=
"func_signature">
29434 <primary>pg_replication_origin_session_reset
</primary>
29436 <function>pg_replication_origin_session_reset
</function> ()
29437 <returnvalue>void
</returnvalue>
29440 Cancels the effects
29441 of
<function>pg_replication_origin_session_setup()
</function>.
29446 <entry role=
"func_table_entry"><para role=
"func_signature">
29448 <primary>pg_replication_origin_session_is_setup
</primary>
29450 <function>pg_replication_origin_session_is_setup
</function> ()
29451 <returnvalue>boolean
</returnvalue>
29454 Returns true if a replication origin has been selected in the
29460 <entry id=
"pg-replication-origin-session-progress" role=
"func_table_entry"><para role=
"func_signature">
29462 <primary>pg_replication_origin_session_progress
</primary>
29464 <function>pg_replication_origin_session_progress
</function> (
<parameter>flush
</parameter> <type>boolean
</type> )
29465 <returnvalue>pg_lsn
</returnvalue>
29468 Returns the replay location for the replication origin selected in
29469 the current session. The parameter
<parameter>flush
</parameter>
29470 determines whether the corresponding local transaction will be
29471 guaranteed to have been flushed to disk or not.
29476 <entry id=
"pg-replication-origin-xact-setup" role=
"func_table_entry"><para role=
"func_signature">
29478 <primary>pg_replication_origin_xact_setup
</primary>
29480 <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> )
29481 <returnvalue>void
</returnvalue>
29484 Marks the current transaction as replaying a transaction that has
29485 committed at the given
<acronym>LSN
</acronym> and timestamp. Can
29486 only be called when a replication origin has been selected
29487 using
<function>pg_replication_origin_session_setup
</function>.
29492 <entry id=
"pg-replication-origin-xact-reset" role=
"func_table_entry"><para role=
"func_signature">
29494 <primary>pg_replication_origin_xact_reset
</primary>
29496 <function>pg_replication_origin_xact_reset
</function> ()
29497 <returnvalue>void
</returnvalue>
29500 Cancels the effects of
29501 <function>pg_replication_origin_xact_setup()
</function>.
29506 <entry id=
"pg-replication-origin-advance" role=
"func_table_entry"><para role=
"func_signature">
29508 <primary>pg_replication_origin_advance
</primary>
29510 <function>pg_replication_origin_advance
</function> (
<parameter>node_name
</parameter> <type>text
</type>,
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
29511 <returnvalue>void
</returnvalue>
29514 Sets replication progress for the given node to the given
29515 location. This is primarily useful for setting up the initial
29516 location, or setting a new location after configuration changes and
29517 similar. Be aware that careless use of this function can lead to
29518 inconsistently replicated data.
29523 <entry id=
"pg-replication-origin-progress" role=
"func_table_entry"><para role=
"func_signature">
29525 <primary>pg_replication_origin_progress
</primary>
29527 <function>pg_replication_origin_progress
</function> (
<parameter>node_name
</parameter> <type>text
</type>,
<parameter>flush
</parameter> <type>boolean
</type> )
29528 <returnvalue>pg_lsn
</returnvalue>
29531 Returns the replay location for the given replication origin. The
29532 parameter
<parameter>flush
</parameter> determines whether the
29533 corresponding local transaction will be guaranteed to have been
29534 flushed to disk or not.
29539 <entry id=
"pg-logical-emit-message" role=
"func_table_entry"><para role=
"func_signature">
29541 <primary>pg_logical_emit_message
</primary>
29543 <function>pg_logical_emit_message
</function> (
<parameter>transactional
</parameter> <type>boolean
</type>,
<parameter>prefix
</parameter> <type>text
</type>,
<parameter>content
</parameter> <type>text
</type> <optional>,
<parameter>flush
</parameter> <type>boolean
</type> <literal>DEFAULT
</literal> <literal>false
</literal></optional> )
29544 <returnvalue>pg_lsn
</returnvalue>
29546 <para role=
"func_signature">
29547 <function>pg_logical_emit_message
</function> (
<parameter>transactional
</parameter> <type>boolean
</type>,
<parameter>prefix
</parameter> <type>text
</type>,
<parameter>content
</parameter> <type>bytea
</type> <optional>,
<parameter>flush
</parameter> <type>boolean
</type> <literal>DEFAULT
</literal> <literal>false
</literal></optional> )
29548 <returnvalue>pg_lsn
</returnvalue>
29551 Emits a logical decoding message. This can be used to pass generic
29552 messages to logical decoding plugins through
29553 WAL. The
<parameter>transactional
</parameter> parameter specifies if
29554 the message should be part of the current transaction, or if it should
29555 be written immediately and decoded as soon as the logical decoder
29556 reads the record. The
<parameter>prefix
</parameter> parameter is a
29557 textual prefix that can be used by logical decoding plugins to easily
29558 recognize messages that are interesting for them.
29559 The
<parameter>content
</parameter> parameter is the content of the
29560 message, given either in text or binary form.
29561 The
<parameter>flush
</parameter> parameter (default set to
29562 <literal>false
</literal>) controls if the message is immediately
29563 flushed to WAL or not.
<parameter>flush
</parameter> has no effect
29564 with
<parameter>transactional
</parameter>, as the message's WAL
29565 record is flushed along with its transaction.
29570 <entry id=
"pg-sync-replication-slots" role=
"func_table_entry"><para role=
"func_signature">
29572 <primary>pg_sync_replication_slots
</primary>
29574 <function>pg_sync_replication_slots
</function> ()
29575 <returnvalue>void
</returnvalue>
29578 Synchronize the logical failover replication slots from the primary
29579 server to the standby server. This function can only be executed on the
29580 standby server. Temporary synced slots, if any, cannot be used for
29581 logical decoding and must be dropped after promotion. See
29582 <xref linkend=
"logicaldecoding-replication-slots-synchronization"/> for details.
29583 Note that this function cannot be executed if
29584 <link linkend=
"guc-sync-replication-slots"><varname>
29585 sync_replication_slots
</varname></link> is enabled and the slotsync
29586 worker is already running to perform the synchronization of slots.
29591 If, after executing the function,
29592 <link linkend=
"guc-hot-standby-feedback">
29593 <varname>hot_standby_feedback
</varname></link> is disabled on
29594 the standby or the physical slot configured in
29595 <link linkend=
"guc-primary-slot-name">
29596 <varname>primary_slot_name
</varname></link> is
29597 removed, then it is possible that the necessary rows of the
29598 synchronized slot will be removed by the VACUUM process on the primary
29599 server, resulting in the synchronized slot becoming invalidated.
29611 <sect2 id=
"functions-admin-dbobject">
29612 <title>Database Object Management Functions
</title>
29615 The functions shown in
<xref linkend=
"functions-admin-dbsize"/> calculate
29616 the disk space usage of database objects, or assist in presentation
29617 or understanding of usage results.
<literal>bigint
</literal> results
29618 are measured in bytes. If an OID that does
29619 not represent an existing object is passed to one of these
29620 functions,
<literal>NULL
</literal> is returned.
29623 <table id=
"functions-admin-dbsize">
29624 <title>Database Object Size Functions
</title>
29628 <entry role=
"func_table_entry"><para role=
"func_signature">
29639 <entry role=
"func_table_entry"><para role=
"func_signature">
29641 <primary>pg_column_size
</primary>
29643 <function>pg_column_size
</function> (
<type>"any"</type> )
29644 <returnvalue>integer
</returnvalue>
29647 Shows the number of bytes used to store any individual data value. If
29648 applied directly to a table column value, this reflects any
29649 compression that was done.
29654 <entry role=
"func_table_entry"><para role=
"func_signature">
29656 <primary>pg_column_compression
</primary>
29658 <function>pg_column_compression
</function> (
<type>"any"</type> )
29659 <returnvalue>text
</returnvalue>
29662 Shows the compression algorithm that was used to compress
29663 an individual variable-length value. Returns
<literal>NULL
</literal>
29664 if the value is not compressed.
29669 <entry role=
"func_table_entry"><para role=
"func_signature">
29671 <primary>pg_column_toast_chunk_id
</primary>
29673 <function>pg_column_toast_chunk_id
</function> (
<type>"any"</type> )
29674 <returnvalue>oid
</returnvalue>
29677 Shows the
<structfield>chunk_id
</structfield> of an on-disk
29678 <acronym>TOAST
</acronym>ed value. Returns
<literal>NULL
</literal>
29679 if the value is un-
<acronym>TOAST
</acronym>ed or not on-disk. See
29680 <xref linkend=
"storage-toast"/> for more information about
29681 <acronym>TOAST
</acronym>.
29686 <entry role=
"func_table_entry"><para role=
"func_signature">
29688 <primary>pg_database_size
</primary>
29690 <function>pg_database_size
</function> (
<type>name
</type> )
29691 <returnvalue>bigint
</returnvalue>
29693 <para role=
"func_signature">
29694 <function>pg_database_size
</function> (
<type>oid
</type> )
29695 <returnvalue>bigint
</returnvalue>
29698 Computes the total disk space used by the database with the specified
29699 name or OID. To use this function, you must
29700 have
<literal>CONNECT
</literal> privilege on the specified database
29701 (which is granted by default) or have privileges of
29702 the
<literal>pg_read_all_stats
</literal> role.
29707 <entry role=
"func_table_entry"><para role=
"func_signature">
29709 <primary>pg_indexes_size
</primary>
29711 <function>pg_indexes_size
</function> (
<type>regclass
</type> )
29712 <returnvalue>bigint
</returnvalue>
29715 Computes the total disk space used by indexes attached to the
29721 <entry role=
"func_table_entry"><para role=
"func_signature">
29723 <primary>pg_relation_size
</primary>
29725 <function>pg_relation_size
</function> (
<parameter>relation
</parameter> <type>regclass
</type> <optional>,
<parameter>fork
</parameter> <type>text
</type> </optional> )
29726 <returnvalue>bigint
</returnvalue>
29729 Computes the disk space used by one
<quote>fork
</quote> of the
29730 specified relation. (Note that for most purposes it is more
29731 convenient to use the higher-level
29732 functions
<function>pg_total_relation_size
</function>
29733 or
<function>pg_table_size
</function>, which sum the sizes of all
29734 forks.) With one argument, this returns the size of the main data
29735 fork of the relation. The second argument can be provided to specify
29736 which fork to examine:
29737 <itemizedlist spacing=
"compact">
29740 <literal>main
</literal> returns the size of the main
29741 data fork of the relation.
29746 <literal>fsm
</literal> returns the size of the Free Space Map
29747 (see
<xref linkend=
"storage-fsm"/>) associated with the relation.
29752 <literal>vm
</literal> returns the size of the Visibility Map
29753 (see
<xref linkend=
"storage-vm"/>) associated with the relation.
29758 <literal>init
</literal> returns the size of the initialization
29759 fork, if any, associated with the relation.
29767 <entry role=
"func_table_entry"><para role=
"func_signature">
29769 <primary>pg_size_bytes
</primary>
29771 <function>pg_size_bytes
</function> (
<type>text
</type> )
29772 <returnvalue>bigint
</returnvalue>
29775 Converts a size in human-readable format (as returned
29776 by
<function>pg_size_pretty
</function>) into bytes. Valid units are
29777 <literal>bytes
</literal>,
<literal>B
</literal>,
<literal>kB
</literal>,
29778 <literal>MB
</literal>,
<literal>GB
</literal>,
<literal>TB
</literal>,
29779 and
<literal>PB
</literal>.
29784 <entry role=
"func_table_entry"><para role=
"func_signature">
29786 <primary>pg_size_pretty
</primary>
29788 <function>pg_size_pretty
</function> (
<type>bigint
</type> )
29789 <returnvalue>text
</returnvalue>
29791 <para role=
"func_signature">
29792 <function>pg_size_pretty
</function> (
<type>numeric
</type> )
29793 <returnvalue>text
</returnvalue>
29796 Converts a size in bytes into a more easily human-readable format with
29797 size units (bytes, kB, MB, GB, TB, or PB as appropriate). Note that the
29798 units are powers of
2 rather than powers of
10, so
1kB is
1024 bytes,
29799 1MB is
1024<superscript>2</superscript> =
1048576 bytes, and so on.
29804 <entry role=
"func_table_entry"><para role=
"func_signature">
29806 <primary>pg_table_size
</primary>
29808 <function>pg_table_size
</function> (
<type>regclass
</type> )
29809 <returnvalue>bigint
</returnvalue>
29812 Computes the disk space used by the specified table, excluding indexes
29813 (but including its TOAST table if any, free space map, and visibility
29819 <entry role=
"func_table_entry"><para role=
"func_signature">
29821 <primary>pg_tablespace_size
</primary>
29823 <function>pg_tablespace_size
</function> (
<type>name
</type> )
29824 <returnvalue>bigint
</returnvalue>
29826 <para role=
"func_signature">
29827 <function>pg_tablespace_size
</function> (
<type>oid
</type> )
29828 <returnvalue>bigint
</returnvalue>
29831 Computes the total disk space used in the tablespace with the
29832 specified name or OID. To use this function, you must
29833 have
<literal>CREATE
</literal> privilege on the specified tablespace
29834 or have privileges of the
<literal>pg_read_all_stats
</literal> role,
29835 unless it is the default tablespace for the current database.
29840 <entry role=
"func_table_entry"><para role=
"func_signature">
29842 <primary>pg_total_relation_size
</primary>
29844 <function>pg_total_relation_size
</function> (
<type>regclass
</type> )
29845 <returnvalue>bigint
</returnvalue>
29848 Computes the total disk space used by the specified table, including
29849 all indexes and
<acronym>TOAST
</acronym> data. The result is
29850 equivalent to
<function>pg_table_size
</function>
29851 <literal>+
</literal> <function>pg_indexes_size
</function>.
29859 The functions above that operate on tables or indexes accept a
29860 <type>regclass
</type> argument, which is simply the OID of the table or index
29861 in the
<structname>pg_class
</structname> system catalog. You do not have to look up
29862 the OID by hand, however, since the
<type>regclass
</type> data type's input
29863 converter will do the work for you. See
<xref linkend=
"datatype-oid"/>
29868 The functions shown in
<xref linkend=
"functions-admin-dblocation"/> assist
29869 in identifying the specific disk files associated with database objects.
29872 <table id=
"functions-admin-dblocation">
29873 <title>Database Object Location Functions
</title>
29877 <entry role=
"func_table_entry"><para role=
"func_signature">
29888 <entry role=
"func_table_entry"><para role=
"func_signature">
29890 <primary>pg_relation_filenode
</primary>
29892 <function>pg_relation_filenode
</function> (
<parameter>relation
</parameter> <type>regclass
</type> )
29893 <returnvalue>oid
</returnvalue>
29896 Returns the
<quote>filenode
</quote> number currently assigned to the
29897 specified relation. The filenode is the base component of the file
29898 name(s) used for the relation (see
29899 <xref linkend=
"storage-file-layout"/> for more information).
29900 For most relations the result is the same as
29901 <structname>pg_class
</structname>.
<structfield>relfilenode
</structfield>,
29902 but for certain system catalogs
<structfield>relfilenode
</structfield>
29903 is zero and this function must be used to get the correct value. The
29904 function returns NULL if passed a relation that does not have storage,
29910 <entry role=
"func_table_entry"><para role=
"func_signature">
29912 <primary>pg_relation_filepath
</primary>
29914 <function>pg_relation_filepath
</function> (
<parameter>relation
</parameter> <type>regclass
</type> )
29915 <returnvalue>text
</returnvalue>
29918 Returns the entire file path name (relative to the database cluster's
29919 data directory,
<varname>PGDATA
</varname>) of the relation.
29924 <entry role=
"func_table_entry"><para role=
"func_signature">
29926 <primary>pg_filenode_relation
</primary>
29928 <function>pg_filenode_relation
</function> (
<parameter>tablespace
</parameter> <type>oid
</type>,
<parameter>filenode
</parameter> <type>oid
</type> )
29929 <returnvalue>regclass
</returnvalue>
29932 Returns a relation's OID given the tablespace OID and filenode it is
29933 stored under. This is essentially the inverse mapping of
29934 <function>pg_relation_filepath
</function>. For a relation in the
29935 database's default tablespace, the tablespace can be specified as zero.
29936 Returns
<literal>NULL
</literal> if no relation in the current database
29937 is associated with the given values.
29945 <xref linkend=
"functions-admin-collation"/> lists functions used to manage
29949 <table id=
"functions-admin-collation">
29950 <title>Collation Management Functions
</title>
29954 <entry role=
"func_table_entry"><para role=
"func_signature">
29965 <entry role=
"func_table_entry"><para role=
"func_signature">
29967 <primary>pg_collation_actual_version
</primary>
29969 <function>pg_collation_actual_version
</function> (
<type>oid
</type> )
29970 <returnvalue>text
</returnvalue>
29973 Returns the actual version of the collation object as it is currently
29974 installed in the operating system. If this is different from the
29976 <structname>pg_collation
</structname>.
<structfield>collversion
</structfield>,
29977 then objects depending on the collation might need to be rebuilt. See
29978 also
<xref linkend=
"sql-altercollation"/>.
29983 <entry role=
"func_table_entry"><para role=
"func_signature">
29985 <primary>pg_database_collation_actual_version
</primary>
29987 <function>pg_database_collation_actual_version
</function> (
<type>oid
</type> )
29988 <returnvalue>text
</returnvalue>
29991 Returns the actual version of the database's collation as it is currently
29992 installed in the operating system. If this is different from the
29994 <structname>pg_database
</structname>.
<structfield>datcollversion
</structfield>,
29995 then objects depending on the collation might need to be rebuilt. See
29996 also
<xref linkend=
"sql-alterdatabase"/>.
30001 <entry role=
"func_table_entry"><para role=
"func_signature">
30003 <primary>pg_import_system_collations
</primary>
30005 <function>pg_import_system_collations
</function> (
<parameter>schema
</parameter> <type>regnamespace
</type> )
30006 <returnvalue>integer
</returnvalue>
30009 Adds collations to the system
30010 catalog
<structname>pg_collation
</structname> based on all the locales
30011 it finds in the operating system. This is
30012 what
<command>initdb
</command> uses; see
30013 <xref linkend=
"collation-managing"/> for more details. If additional
30014 locales are installed into the operating system later on, this
30015 function can be run again to add collations for the new locales.
30016 Locales that match existing entries
30017 in
<structname>pg_collation
</structname> will be skipped. (But
30018 collation objects based on locales that are no longer present in the
30019 operating system are not removed by this function.)
30020 The
<parameter>schema
</parameter> parameter would typically
30021 be
<literal>pg_catalog
</literal>, but that is not a requirement; the
30022 collations could be installed into some other schema as well. The
30023 function returns the number of new collation objects it created.
30024 Use of this function is restricted to superusers.
30032 <xref linkend=
"functions-admin-statsmod"/> lists functions used to
30033 manipulate statistics.
30034 These functions cannot be executed during recovery.
30037 Changes made by these statistics manipulation functions are likely to be
30038 overwritten by
<link linkend=
"autovacuum">autovacuum
</link> (or manual
30039 <command>VACUUM
</command> or
<command>ANALYZE
</command>) and should be
30040 considered temporary.
30045 <table id=
"functions-admin-statsmod">
30046 <title>Database Object Statistics Manipulation Functions
</title>
30050 <entry role=
"func_table_entry"><para role=
"func_signature">
30061 <entry role=
"func_table_entry">
30062 <para role=
"func_signature">
30064 <primary>pg_set_relation_stats
</primary>
30066 <function>pg_set_relation_stats
</function> (
30067 <parameter>relation
</parameter> <type>regclass
</type>
30068 <optional>,
<parameter>relpages
</parameter> <type>integer
</type></optional>
30069 <optional>,
<parameter>reltuples
</parameter> <type>real
</type></optional>
30070 <optional>,
<parameter>relallvisible
</parameter> <type>integer
</type></optional> )
30071 <returnvalue>void
</returnvalue>
30074 Updates relation-level statistics for the given relation to the
30075 specified values. The parameters correspond to columns in
<link
30076 linkend=
"catalog-pg-class"><structname>pg_class
</structname></link>. Unspecified
30077 or
<literal>NULL
</literal> values leave the setting unchanged.
30080 Ordinarily, these statistics are collected automatically or updated
30081 as a part of
<xref linkend=
"sql-vacuum"/> or
<xref
30082 linkend=
"sql-analyze"/>, so it's not necessary to call this
30083 function. However, it may be useful when testing the effects of
30084 statistics on the planner to understand or anticipate plan changes.
30087 The caller must have the
<literal>MAINTAIN
</literal> privilege on
30088 the table or be the owner of the database.
30091 The value of
<structfield>relpages
</structfield> must be greater than
30092 or equal to
<literal>-
1</literal>,
30093 <structfield>reltuples
</structfield> must be greater than or equal to
30094 <literal>-
1.0</literal>, and
<structfield>relallvisible
</structfield>
30095 must be greater than or equal to
<literal>0</literal>.
30101 <entry role=
"func_table_entry">
30102 <para role=
"func_signature">
30104 <primary>pg_clear_relation_stats
</primary>
30106 <function>pg_clear_relation_stats
</function> (
<parameter>relation
</parameter> <type>regclass
</type> )
30107 <returnvalue>void
</returnvalue>
30110 Clears table-level statistics for the given relation, as though the
30111 table was newly created.
30114 The caller must have the
<literal>MAINTAIN
</literal> privilege on
30115 the table or be the owner of the database.
30121 <entry role=
"func_table_entry"><para role=
"func_signature">
30123 <primary>pg_restore_relation_stats
</primary>
30125 <function>pg_restore_relation_stats
</function> (
30126 <literal>VARIADIC
</literal> <parameter>kwargs
</parameter> <type>"any"</type> )
30127 <returnvalue>boolean
</returnvalue>
30130 Similar to
<function>pg_set_relation_stats()
</function>, but intended
30131 for bulk restore of relation statistics. The tracked statistics may
30132 change from version to version, so the primary purpose of this
30133 function is to maintain a consistent function signature to avoid
30134 errors when restoring statistics from previous versions.
30137 Arguments are passed as pairs of
<replaceable>argname
</replaceable>
30138 and
<replaceable>argvalue
</replaceable>, where
30139 <replaceable>argname
</replaceable> corresponds to a named argument in
30140 <function>pg_set_relation_stats()
</function> and
30141 <replaceable>argvalue
</replaceable> is of the corresponding type.
30144 Additionally, this function supports argument name
30145 <literal>version
</literal> of type
<type>integer
</type>, which
30146 specifies the version from which the statistics originated, improving
30147 interpretation of older statistics.
30150 For example, to set the
<structname>relpages
</structname> and
30151 <structname>reltuples
</structname> of the table
30152 <structname>mytable
</structname>:
30154 SELECT pg_restore_relation_stats(
30155 'relation', 'mytable'::regclass,
30156 'relpages',
173::integer,
30157 'reltuples',
10000::float4);
30161 Minor errors are reported as a
<literal>WARNING
</literal> and
30162 ignored, and remaining statistics will still be restored. If all
30163 specified statistics are successfully restored, return
30164 <literal>true
</literal>, otherwise
<literal>false
</literal>.
30170 <entry role=
"func_table_entry">
30171 <para role=
"func_signature">
30173 <primary>pg_set_attribute_stats
</primary>
30175 <function>pg_set_attribute_stats
</function> (
30176 <parameter>relation
</parameter> <type>regclass
</type>,
30177 <parameter>attname
</parameter> <type>name
</type>,
30178 <parameter>inherited
</parameter> <type>boolean
</type>
30179 <optional>,
<parameter>null_frac
</parameter> <type>real
</type></optional>
30180 <optional>,
<parameter>avg_width
</parameter> <type>integer
</type></optional>
30181 <optional>,
<parameter>n_distinct
</parameter> <type>real
</type></optional>
30182 <optional>,
<parameter>most_common_vals
</parameter> <type>text
</type>,
<parameter>most_common_freqs
</parameter> <type>real[]
</type> </optional>
30183 <optional>,
<parameter>histogram_bounds
</parameter> <type>text
</type> </optional>
30184 <optional>,
<parameter>correlation
</parameter> <type>real
</type> </optional>
30185 <optional>,
<parameter>most_common_elems
</parameter> <type>text
</type>,
<parameter>most_common_elem_freqs
</parameter> <type>real[]
</type> </optional>
30186 <optional>,
<parameter>elem_count_histogram
</parameter> <type>real[]
</type> </optional>
30187 <optional>,
<parameter>range_length_histogram
</parameter> <type>text
</type> </optional>
30188 <optional>,
<parameter>range_empty_frac
</parameter> <type>real
</type> </optional>
30189 <optional>,
<parameter>range_bounds_histogram
</parameter> <type>text
</type> </optional> )
30190 <returnvalue>void
</returnvalue>
30193 Creates or updates attribute-level statistics for the given relation
30194 and attribute name to the specified values. The parameters correspond
30195 to attributes of the same name found in the
<link
30196 linkend=
"view-pg-stats"><structname>pg_stats
</structname></link>
30200 Optional parameters default to
<literal>NULL
</literal>, which leave
30201 the corresponding statistic unchanged.
30204 Ordinarily, these statistics are collected automatically or updated
30205 as a part of
<xref linkend=
"sql-vacuum"/> or
<xref
30206 linkend=
"sql-analyze"/>, so it's not necessary to call this
30207 function. However, it may be useful when testing the effects of
30208 statistics on the planner to understand or anticipate plan changes.
30211 The caller must have the
<literal>MAINTAIN
</literal> privilege on
30212 the table or be the owner of the database.
30218 <entry role=
"func_table_entry">
30219 <para role=
"func_signature">
30221 <primary>pg_clear_attribute_stats
</primary>
30223 <function>pg_clear_attribute_stats
</function> (
30224 <parameter>relation
</parameter> <type>regclass
</type>,
30225 <parameter>attname
</parameter> <type>name
</type>,
30226 <parameter>inherited
</parameter> <type>boolean
</type> )
30227 <returnvalue>void
</returnvalue>
30230 Clears table-level statistics for the given relation attribute, as
30231 though the table was newly created.
30234 The caller must have the
<literal>MAINTAIN
</literal> privilege on
30235 the table or be the owner of the database.
30241 <entry role=
"func_table_entry"><para role=
"func_signature">
30243 <primary>pg_restore_attribute_stats
</primary>
30245 <function>pg_restore_attribute_stats
</function> (
30246 <literal>VARIADIC
</literal> <parameter>kwargs
</parameter> <type>"any"</type> )
30247 <returnvalue>boolean
</returnvalue>
30250 Similar to
<function>pg_set_attribute_stats()
</function>, but
30251 intended for bulk restore of attribute statistics. The tracked
30252 statistics may change from version to version, so the primary purpose
30253 of this function is to maintain a consistent function signature to
30254 avoid errors when restoring statistics from previous versions.
30257 Arguments are passed as pairs of
<replaceable>argname
</replaceable>
30258 and
<replaceable>argvalue
</replaceable>, where
30259 <replaceable>argname
</replaceable> corresponds to a named argument in
30260 <function>pg_set_attribute_stats()
</function> and
30261 <replaceable>argvalue
</replaceable> is of the corresponding type.
30264 Additionally, this function supports argument name
30265 <literal>version
</literal> of type
<type>integer
</type>, which
30266 specifies the version from which the statistics originated, improving
30267 interpretation of older statistics.
30270 For example, to set the
<structname>avg_width
</structname> and
30271 <structname>null_frac
</structname> for the attribute
30272 <structname>col1
</structname> of the table
30273 <structname>mytable
</structname>:
30275 SELECT pg_restore_attribute_stats(
30276 'relation', 'mytable'::regclass,
30277 'attname', 'col1'::name,
30278 'inherited', false,
30279 'avg_width',
125::integer,
30280 'null_frac',
0.5::real);
30284 Minor errors are reported as a
<literal>WARNING
</literal> and
30285 ignored, and remaining statistics will still be restored. If all
30286 specified statistics are successfully restored, return
30287 <literal>true
</literal>, otherwise
<literal>false
</literal>.
30296 <xref linkend=
"functions-info-partition"/> lists functions that provide
30297 information about the structure of partitioned tables.
30300 <table id=
"functions-info-partition">
30301 <title>Partitioning Information Functions
</title>
30305 <entry role=
"func_table_entry"><para role=
"func_signature">
30316 <entry role=
"func_table_entry"><para role=
"func_signature">
30318 <primary>pg_partition_tree
</primary>
30320 <function>pg_partition_tree
</function> (
<type>regclass
</type> )
30321 <returnvalue>setof record
</returnvalue>
30322 (
<parameter>relid
</parameter> <type>regclass
</type>,
30323 <parameter>parentrelid
</parameter> <type>regclass
</type>,
30324 <parameter>isleaf
</parameter> <type>boolean
</type>,
30325 <parameter>level
</parameter> <type>integer
</type> )
30328 Lists the tables or indexes in the partition tree of the
30329 given partitioned table or partitioned index, with one row for each
30330 partition. Information provided includes the OID of the partition,
30331 the OID of its immediate parent, a boolean value telling if the
30332 partition is a leaf, and an integer telling its level in the hierarchy.
30333 The level value is
0 for the input table or index,
1 for its
30334 immediate child partitions,
2 for their partitions, and so on.
30335 Returns no rows if the relation does not exist or is not a partition
30336 or partitioned table.
30341 <entry role=
"func_table_entry"><para role=
"func_signature">
30343 <primary>pg_partition_ancestors
</primary>
30345 <function>pg_partition_ancestors
</function> (
<type>regclass
</type> )
30346 <returnvalue>setof regclass
</returnvalue>
30349 Lists the ancestor relations of the given partition,
30350 including the relation itself. Returns no rows if the relation
30351 does not exist or is not a partition or partitioned table.
30356 <entry role=
"func_table_entry"><para role=
"func_signature">
30358 <primary>pg_partition_root
</primary>
30360 <function>pg_partition_root
</function> (
<type>regclass
</type> )
30361 <returnvalue>regclass
</returnvalue>
30364 Returns the top-most parent of the partition tree to which the given
30365 relation belongs. Returns
<literal>NULL
</literal> if the relation
30366 does not exist or is not a partition or partitioned table.
30374 For example, to check the total size of the data contained in a
30375 partitioned table
<structname>measurement
</structname>, one could use the
30378 SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
30379 FROM pg_partition_tree('measurement');
30385 <sect2 id=
"functions-admin-index">
30386 <title>Index Maintenance Functions
</title>
30389 <xref linkend=
"functions-admin-index-table"/> shows the functions
30390 available for index maintenance tasks. (Note that these maintenance
30391 tasks are normally done automatically by autovacuum; use of these
30392 functions is only required in special cases.)
30393 These functions cannot be executed during recovery.
30394 Use of these functions is restricted to superusers and the owner
30395 of the given index.
30398 <table id=
"functions-admin-index-table">
30399 <title>Index Maintenance Functions
</title>
30403 <entry role=
"func_table_entry"><para role=
"func_signature">
30414 <entry role=
"func_table_entry"><para role=
"func_signature">
30416 <primary>brin_summarize_new_values
</primary>
30418 <function>brin_summarize_new_values
</function> (
<parameter>index
</parameter> <type>regclass
</type> )
30419 <returnvalue>integer
</returnvalue>
30422 Scans the specified BRIN index to find page ranges in the base table
30423 that are not currently summarized by the index; for any such range it
30424 creates a new summary index tuple by scanning those table pages.
30425 Returns the number of new page range summaries that were inserted
30431 <entry role=
"func_table_entry"><para role=
"func_signature">
30433 <primary>brin_summarize_range
</primary>
30435 <function>brin_summarize_range
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>blockNumber
</parameter> <type>bigint
</type> )
30436 <returnvalue>integer
</returnvalue>
30439 Summarizes the page range covering the given block, if not already
30440 summarized. This is
30441 like
<function>brin_summarize_new_values
</function> except that it
30442 only processes the page range that covers the given table block number.
30447 <entry role=
"func_table_entry"><para role=
"func_signature">
30449 <primary>brin_desummarize_range
</primary>
30451 <function>brin_desummarize_range
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>blockNumber
</parameter> <type>bigint
</type> )
30452 <returnvalue>void
</returnvalue>
30455 Removes the BRIN index tuple that summarizes the page range covering
30456 the given table block, if there is one.
30461 <entry role=
"func_table_entry"><para role=
"func_signature">
30463 <primary>gin_clean_pending_list
</primary>
30465 <function>gin_clean_pending_list
</function> (
<parameter>index
</parameter> <type>regclass
</type> )
30466 <returnvalue>bigint
</returnvalue>
30469 Cleans up the
<quote>pending
</quote> list of the specified GIN index
30470 by moving entries in it, in bulk, to the main GIN data structure.
30471 Returns the number of pages removed from the pending list.
30472 If the argument is a GIN index built with
30473 the
<literal>fastupdate
</literal> option disabled, no cleanup happens
30474 and the result is zero, because the index doesn't have a pending list.
30475 See
<xref linkend=
"gin-fast-update"/> and
<xref linkend=
"gin-tips"/>
30476 for details about the pending list and
<literal>fastupdate
</literal>
30486 <sect2 id=
"functions-admin-genfile">
30487 <title>Generic File Access Functions
</title>
30490 The functions shown in
<xref
30491 linkend=
"functions-admin-genfile-table"/> provide native access to
30492 files on the machine hosting the server. Only files within the
30493 database cluster directory and the
<varname>log_directory
</varname> can be
30494 accessed, unless the user is a superuser or is granted the role
30495 <literal>pg_read_server_files
</literal>. Use a relative path for files in
30496 the cluster directory, and a path matching the
<varname>log_directory
</varname>
30497 configuration setting for log files.
30501 Note that granting users the EXECUTE privilege on
30502 <function>pg_read_file()
</function>, or related functions, allows them the
30503 ability to read any file on the server that the database server process can
30504 read; these functions bypass all in-database privilege checks. This means
30505 that, for example, a user with such access is able to read the contents of
30506 the
<structname>pg_authid
</structname> table where authentication
30507 information is stored, as well as read any table data in the database.
30508 Therefore, granting access to these functions should be carefully
30513 When granting privilege on these functions, note that the table entries
30514 showing optional parameters are mostly implemented as several physical
30515 functions with different parameter lists. Privilege must be granted
30516 separately on each such function, if it is to be
30517 used.
<application>psql
</application>'s
<command>\df
</command> command
30518 can be useful to check what the actual function signatures are.
30522 Some of these functions take an optional
<parameter>missing_ok
</parameter>
30523 parameter, which specifies the behavior when the file or directory does
30524 not exist. If
<literal>true
</literal>, the function
30525 returns
<literal>NULL
</literal> or an empty result set, as appropriate.
30526 If
<literal>false
</literal>, an error is raised. (Failure conditions
30527 other than
<quote>file not found
</quote> are reported as errors in any
30528 case.) The default is
<literal>false
</literal>.
30531 <table id=
"functions-admin-genfile-table">
30532 <title>Generic File Access Functions
</title>
30536 <entry role=
"func_table_entry"><para role=
"func_signature">
30547 <entry role=
"func_table_entry"><para role=
"func_signature">
30549 <primary>pg_ls_dir
</primary>
30551 <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> )
30552 <returnvalue>setof text
</returnvalue>
30555 Returns the names of all files (and directories and other special
30556 files) in the specified
30557 directory. The
<parameter>include_dot_dirs
</parameter> parameter
30558 indicates whether
<quote>.
</quote> and
<quote>..
</quote> are to be
30559 included in the result set; the default is to exclude them. Including
30560 them can be useful when
<parameter>missing_ok
</parameter>
30561 is
<literal>true
</literal>, to distinguish an empty directory from a
30562 non-existent directory.
30565 This function is restricted to superusers by default, but other users
30566 can be granted EXECUTE to run the function.
30571 <entry role=
"func_table_entry"><para role=
"func_signature">
30573 <primary>pg_ls_logdir
</primary>
30575 <function>pg_ls_logdir
</function> ()
30576 <returnvalue>setof record
</returnvalue>
30577 (
<parameter>name
</parameter> <type>text
</type>,
30578 <parameter>size
</parameter> <type>bigint
</type>,
30579 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30582 Returns the name, size, and last modification time (mtime) of each
30583 ordinary file in the server's log directory. Filenames beginning with
30584 a dot, directories, and other special files are excluded.
30587 This function is restricted to superusers and roles with privileges of
30588 the
<literal>pg_monitor
</literal> role by default, but other users can
30589 be granted EXECUTE to run the function.
30594 <entry role=
"func_table_entry"><para role=
"func_signature">
30596 <primary>pg_ls_waldir
</primary>
30598 <function>pg_ls_waldir
</function> ()
30599 <returnvalue>setof record
</returnvalue>
30600 (
<parameter>name
</parameter> <type>text
</type>,
30601 <parameter>size
</parameter> <type>bigint
</type>,
30602 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30605 Returns the name, size, and last modification time (mtime) of each
30606 ordinary file in the server's write-ahead log (WAL) directory.
30607 Filenames beginning with a dot, directories, and other special files
30611 This function is restricted to superusers and roles with privileges of
30612 the
<literal>pg_monitor
</literal> role by default, but other users can
30613 be granted EXECUTE to run the function.
30618 <entry role=
"func_table_entry"><para role=
"func_signature">
30620 <primary>pg_ls_logicalmapdir
</primary>
30622 <function>pg_ls_logicalmapdir
</function> ()
30623 <returnvalue>setof record
</returnvalue>
30624 (
<parameter>name
</parameter> <type>text
</type>,
30625 <parameter>size
</parameter> <type>bigint
</type>,
30626 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30629 Returns the name, size, and last modification time (mtime) of each
30630 ordinary file in the server's
<filename>pg_logical/mappings
</filename>
30631 directory. Filenames beginning with a dot, directories, and other
30632 special files are excluded.
30635 This function is restricted to superusers and members of
30636 the
<literal>pg_monitor
</literal> role by default, but other users can
30637 be granted EXECUTE to run the function.
30642 <entry role=
"func_table_entry"><para role=
"func_signature">
30644 <primary>pg_ls_logicalsnapdir
</primary>
30646 <function>pg_ls_logicalsnapdir
</function> ()
30647 <returnvalue>setof record
</returnvalue>
30648 (
<parameter>name
</parameter> <type>text
</type>,
30649 <parameter>size
</parameter> <type>bigint
</type>,
30650 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30653 Returns the name, size, and last modification time (mtime) of each
30654 ordinary file in the server's
<filename>pg_logical/snapshots
</filename>
30655 directory. Filenames beginning with a dot, directories, and other
30656 special files are excluded.
30659 This function is restricted to superusers and members of
30660 the
<literal>pg_monitor
</literal> role by default, but other users can
30661 be granted EXECUTE to run the function.
30666 <entry role=
"func_table_entry"><para role=
"func_signature">
30668 <primary>pg_ls_replslotdir
</primary>
30670 <function>pg_ls_replslotdir
</function> (
<parameter>slot_name
</parameter> <type>text
</type> )
30671 <returnvalue>setof record
</returnvalue>
30672 (
<parameter>name
</parameter> <type>text
</type>,
30673 <parameter>size
</parameter> <type>bigint
</type>,
30674 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30677 Returns the name, size, and last modification time (mtime) of each
30678 ordinary file in the server's
<filename>pg_replslot/slot_name
</filename>
30679 directory, where
<parameter>slot_name
</parameter> is the name of the
30680 replication slot provided as input of the function. Filenames beginning
30681 with a dot, directories, and other special files are excluded.
30684 This function is restricted to superusers and members of
30685 the
<literal>pg_monitor
</literal> role by default, but other users can
30686 be granted EXECUTE to run the function.
30691 <entry role=
"func_table_entry"><para role=
"func_signature">
30693 <primary>pg_ls_summariesdir
</primary>
30695 <function>pg_ls_summariesdir
</function> ()
30696 <returnvalue>setof record
</returnvalue>
30697 (
<parameter>name
</parameter> <type>text
</type>,
30698 <parameter>size
</parameter> <type>bigint
</type>,
30699 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30702 Returns the name, size, and last modification time (mtime) of each
30703 ordinary file in the server's WAL summaries directory
30704 (
<filename>pg_wal/summaries
</filename>). Filenames beginning
30705 with a dot, directories, and other special files are excluded.
30708 This function is restricted to superusers and members of
30709 the
<literal>pg_monitor
</literal> role by default, but other users can
30710 be granted EXECUTE to run the function.
30715 <entry role=
"func_table_entry"><para role=
"func_signature">
30717 <primary>pg_ls_archive_statusdir
</primary>
30719 <function>pg_ls_archive_statusdir
</function> ()
30720 <returnvalue>setof record
</returnvalue>
30721 (
<parameter>name
</parameter> <type>text
</type>,
30722 <parameter>size
</parameter> <type>bigint
</type>,
30723 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30726 Returns the name, size, and last modification time (mtime) of each
30727 ordinary file in the server's WAL archive status directory
30728 (
<filename>pg_wal/archive_status
</filename>). Filenames beginning
30729 with a dot, directories, and other special files are excluded.
30732 This function is restricted to superusers and members of
30733 the
<literal>pg_monitor
</literal> role by default, but other users can
30734 be granted EXECUTE to run the function.
30739 <entry role=
"func_table_entry"><para role=
"func_signature">
30742 <primary>pg_ls_tmpdir
</primary>
30744 <function>pg_ls_tmpdir
</function> (
<optional> <parameter>tablespace
</parameter> <type>oid
</type> </optional> )
30745 <returnvalue>setof record
</returnvalue>
30746 (
<parameter>name
</parameter> <type>text
</type>,
30747 <parameter>size
</parameter> <type>bigint
</type>,
30748 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
30751 Returns the name, size, and last modification time (mtime) of each
30752 ordinary file in the temporary file directory for the
30753 specified
<parameter>tablespace
</parameter>.
30754 If
<parameter>tablespace
</parameter> is not provided,
30755 the
<literal>pg_default
</literal> tablespace is examined. Filenames
30756 beginning with a dot, directories, and other special files are
30760 This function is restricted to superusers and members of
30761 the
<literal>pg_monitor
</literal> role by default, but other users can
30762 be granted EXECUTE to run the function.
30767 <entry role=
"func_table_entry"><para role=
"func_signature">
30769 <primary>pg_read_file
</primary>
30771 <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> )
30772 <returnvalue>text
</returnvalue>
30775 Returns all or part of a text file, starting at the
30776 given byte
<parameter>offset
</parameter>, returning at
30777 most
<parameter>length
</parameter> bytes (less if the end of file is
30778 reached first). If
<parameter>offset
</parameter> is negative, it is
30779 relative to the end of the file. If
<parameter>offset
</parameter>
30780 and
<parameter>length
</parameter> are omitted, the entire file is
30781 returned. The bytes read from the file are interpreted as a string in
30782 the database's encoding; an error is thrown if they are not valid in
30786 This function is restricted to superusers by default, but other users
30787 can be granted EXECUTE to run the function.
30792 <entry role=
"func_table_entry"><para role=
"func_signature">
30794 <primary>pg_read_binary_file
</primary>
30796 <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> )
30797 <returnvalue>bytea
</returnvalue>
30800 Returns all or part of a file. This function is identical to
30801 <function>pg_read_file
</function> except that it can read arbitrary
30802 binary data, returning the result as
<type>bytea
</type>
30803 not
<type>text
</type>; accordingly, no encoding checks are performed.
30806 This function is restricted to superusers by default, but other users
30807 can be granted EXECUTE to run the function.
30810 In combination with the
<function>convert_from
</function> function,
30811 this function can be used to read a text file in a specified encoding
30812 and convert to the database's encoding:
30814 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
30820 <entry role=
"func_table_entry"><para role=
"func_signature">
30822 <primary>pg_stat_file
</primary>
30824 <function>pg_stat_file
</function> (
<parameter>filename
</parameter> <type>text
</type> <optional>,
<parameter>missing_ok
</parameter> <type>boolean
</type> </optional> )
30825 <returnvalue>record
</returnvalue>
30826 (
<parameter>size
</parameter> <type>bigint
</type>,
30827 <parameter>access
</parameter> <type>timestamp with time zone
</type>,
30828 <parameter>modification
</parameter> <type>timestamp with time zone
</type>,
30829 <parameter>change
</parameter> <type>timestamp with time zone
</type>,
30830 <parameter>creation
</parameter> <type>timestamp with time zone
</type>,
30831 <parameter>isdir
</parameter> <type>boolean
</type> )
30834 Returns a record containing the file's size, last access time stamp,
30835 last modification time stamp, last file status change time stamp (Unix
30836 platforms only), file creation time stamp (Windows only), and a flag
30837 indicating if it is a directory.
30840 This function is restricted to superusers by default, but other users
30841 can be granted EXECUTE to run the function.
30851 <sect2 id=
"functions-advisory-locks">
30852 <title>Advisory Lock Functions
</title>
30855 The functions shown in
<xref linkend=
"functions-advisory-locks-table"/>
30856 manage advisory locks. For details about proper use of these functions,
30857 see
<xref linkend=
"advisory-locks"/>.
30861 All these functions are intended to be used to lock application-defined
30862 resources, which can be identified either by a single
64-bit key value or
30863 two
32-bit key values (note that these two key spaces do not overlap).
30864 If another session already holds a conflicting lock on the same resource
30865 identifier, the functions will either wait until the resource becomes
30866 available, or return a
<literal>false
</literal> result, as appropriate for
30868 Locks can be either shared or exclusive: a shared lock does not conflict
30869 with other shared locks on the same resource, only with exclusive locks.
30870 Locks can be taken at session level (so that they are held until released
30871 or the session ends) or at transaction level (so that they are held until
30872 the current transaction ends; there is no provision for manual release).
30873 Multiple session-level lock requests stack, so that if the same resource
30874 identifier is locked three times there must then be three unlock requests
30875 to release the resource in advance of session end.
30878 <table id=
"functions-advisory-locks-table">
30879 <title>Advisory Lock Functions
</title>
30883 <entry role=
"func_table_entry"><para role=
"func_signature">
30894 <entry role=
"func_table_entry"><para role=
"func_signature">
30896 <primary>pg_advisory_lock
</primary>
30898 <function>pg_advisory_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30899 <returnvalue>void
</returnvalue>
30901 <para role=
"func_signature">
30902 <function>pg_advisory_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30903 <returnvalue>void
</returnvalue>
30906 Obtains an exclusive session-level advisory lock, waiting if necessary.
30911 <entry role=
"func_table_entry"><para role=
"func_signature">
30913 <primary>pg_advisory_lock_shared
</primary>
30915 <function>pg_advisory_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30916 <returnvalue>void
</returnvalue>
30918 <para role=
"func_signature">
30919 <function>pg_advisory_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30920 <returnvalue>void
</returnvalue>
30923 Obtains a shared session-level advisory lock, waiting if necessary.
30928 <entry role=
"func_table_entry"><para role=
"func_signature">
30930 <primary>pg_advisory_unlock
</primary>
30932 <function>pg_advisory_unlock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30933 <returnvalue>boolean
</returnvalue>
30935 <para role=
"func_signature">
30936 <function>pg_advisory_unlock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30937 <returnvalue>boolean
</returnvalue>
30940 Releases a previously-acquired exclusive session-level advisory lock.
30941 Returns
<literal>true
</literal> if the lock is successfully released.
30942 If the lock was not held,
<literal>false
</literal> is returned, and in
30943 addition, an SQL warning will be reported by the server.
30948 <entry role=
"func_table_entry"><para role=
"func_signature">
30950 <primary>pg_advisory_unlock_all
</primary>
30952 <function>pg_advisory_unlock_all
</function> ()
30953 <returnvalue>void
</returnvalue>
30956 Releases all session-level advisory locks held by the current session.
30957 (This function is implicitly invoked at session end, even if the
30958 client disconnects ungracefully.)
30963 <entry role=
"func_table_entry"><para role=
"func_signature">
30965 <primary>pg_advisory_unlock_shared
</primary>
30967 <function>pg_advisory_unlock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30968 <returnvalue>boolean
</returnvalue>
30970 <para role=
"func_signature">
30971 <function>pg_advisory_unlock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30972 <returnvalue>boolean
</returnvalue>
30975 Releases a previously-acquired shared session-level advisory lock.
30976 Returns
<literal>true
</literal> if the lock is successfully released.
30977 If the lock was not held,
<literal>false
</literal> is returned, and in
30978 addition, an SQL warning will be reported by the server.
30983 <entry role=
"func_table_entry"><para role=
"func_signature">
30985 <primary>pg_advisory_xact_lock
</primary>
30987 <function>pg_advisory_xact_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
30988 <returnvalue>void
</returnvalue>
30990 <para role=
"func_signature">
30991 <function>pg_advisory_xact_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
30992 <returnvalue>void
</returnvalue>
30995 Obtains an exclusive transaction-level advisory lock, waiting if
31001 <entry role=
"func_table_entry"><para role=
"func_signature">
31003 <primary>pg_advisory_xact_lock_shared
</primary>
31005 <function>pg_advisory_xact_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
31006 <returnvalue>void
</returnvalue>
31008 <para role=
"func_signature">
31009 <function>pg_advisory_xact_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
31010 <returnvalue>void
</returnvalue>
31013 Obtains a shared transaction-level advisory lock, waiting if
31019 <entry role=
"func_table_entry"><para role=
"func_signature">
31021 <primary>pg_try_advisory_lock
</primary>
31023 <function>pg_try_advisory_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
31024 <returnvalue>boolean
</returnvalue>
31026 <para role=
"func_signature">
31027 <function>pg_try_advisory_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
31028 <returnvalue>boolean
</returnvalue>
31031 Obtains an exclusive session-level advisory lock if available.
31032 This will either obtain the lock immediately and
31033 return
<literal>true
</literal>, or return
<literal>false
</literal>
31034 without waiting if the lock cannot be acquired immediately.
31039 <entry role=
"func_table_entry"><para role=
"func_signature">
31041 <primary>pg_try_advisory_lock_shared
</primary>
31043 <function>pg_try_advisory_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
31044 <returnvalue>boolean
</returnvalue>
31046 <para role=
"func_signature">
31047 <function>pg_try_advisory_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
31048 <returnvalue>boolean
</returnvalue>
31051 Obtains a shared session-level advisory lock if available.
31052 This will either obtain the lock immediately and
31053 return
<literal>true
</literal>, or return
<literal>false
</literal>
31054 without waiting if the lock cannot be acquired immediately.
31059 <entry role=
"func_table_entry"><para role=
"func_signature">
31061 <primary>pg_try_advisory_xact_lock
</primary>
31063 <function>pg_try_advisory_xact_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
31064 <returnvalue>boolean
</returnvalue>
31066 <para role=
"func_signature">
31067 <function>pg_try_advisory_xact_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
31068 <returnvalue>boolean
</returnvalue>
31071 Obtains an exclusive transaction-level advisory lock if available.
31072 This will either obtain the lock immediately and
31073 return
<literal>true
</literal>, or return
<literal>false
</literal>
31074 without waiting if the lock cannot be acquired immediately.
31079 <entry role=
"func_table_entry"><para role=
"func_signature">
31081 <primary>pg_try_advisory_xact_lock_shared
</primary>
31083 <function>pg_try_advisory_xact_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
31084 <returnvalue>boolean
</returnvalue>
31086 <para role=
"func_signature">
31087 <function>pg_try_advisory_xact_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
31088 <returnvalue>boolean
</returnvalue>
31091 Obtains a shared transaction-level advisory lock if available.
31092 This will either obtain the lock immediately and
31093 return
<literal>true
</literal>, or return
<literal>false
</literal>
31094 without waiting if the lock cannot be acquired immediately.
31105 <sect1 id=
"functions-trigger">
31106 <title>Trigger Functions
</title>
31109 While many uses of triggers involve user-written trigger functions,
31110 <productname>PostgreSQL
</productname> provides a few built-in trigger
31111 functions that can be used directly in user-defined triggers. These
31112 are summarized in
<xref linkend=
"builtin-triggers-table"/>.
31113 (Additional built-in trigger functions exist, which implement foreign
31114 key constraints and deferred index constraints. Those are not documented
31115 here since users need not use them directly.)
31119 For more information about creating triggers, see
31120 <xref linkend=
"sql-createtrigger"/>.
31123 <table id=
"builtin-triggers-table">
31124 <title>Built-In Trigger Functions
</title>
31128 <entry role=
"func_table_entry"><para role=
"func_signature">
31142 <entry role=
"func_table_entry"><para role=
"func_signature">
31144 <primary>suppress_redundant_updates_trigger
</primary>
31146 <function>suppress_redundant_updates_trigger
</function> ( )
31147 <returnvalue>trigger
</returnvalue>
31150 Suppresses do-nothing update operations. See below for details.
31153 <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()
</literal>
31158 <entry role=
"func_table_entry"><para role=
"func_signature">
31160 <primary>tsvector_update_trigger
</primary>
31162 <function>tsvector_update_trigger
</function> ( )
31163 <returnvalue>trigger
</returnvalue>
31166 Automatically updates a
<type>tsvector
</type> column from associated
31167 plain-text document column(s). The text search configuration to use
31168 is specified by name as a trigger argument. See
31169 <xref linkend=
"textsearch-update-triggers"/> for details.
31172 <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)
</literal>
31177 <entry role=
"func_table_entry"><para role=
"func_signature">
31179 <primary>tsvector_update_trigger_column
</primary>
31181 <function>tsvector_update_trigger_column
</function> ( )
31182 <returnvalue>trigger
</returnvalue>
31185 Automatically updates a
<type>tsvector
</type> column from associated
31186 plain-text document column(s). The text search configuration to use
31187 is taken from a
<type>regconfig
</type> column of the table. See
31188 <xref linkend=
"textsearch-update-triggers"/> for details.
31191 <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)
</literal>
31199 The
<function>suppress_redundant_updates_trigger
</function> function,
31200 when applied as a row-level
<literal>BEFORE UPDATE
</literal> trigger,
31201 will prevent any update that does not actually change the data in the
31202 row from taking place. This overrides the normal behavior which always
31203 performs a physical row update
31204 regardless of whether or not the data has changed. (This normal behavior
31205 makes updates run faster, since no checking is required, and is also
31206 useful in certain cases.)
31210 Ideally, you should avoid running updates that don't actually
31211 change the data in the record. Redundant updates can cost considerable
31212 unnecessary time, especially if there are lots of indexes to alter,
31213 and space in dead rows that will eventually have to be vacuumed.
31214 However, detecting such situations in client code is not
31215 always easy, or even possible, and writing expressions to detect
31216 them can be error-prone. An alternative is to use
31217 <function>suppress_redundant_updates_trigger
</function>, which will skip
31218 updates that don't change the data. You should use this with care,
31219 however. The trigger takes a small but non-trivial time for each record,
31220 so if most of the records affected by updates do actually change,
31221 use of this trigger will make updates run slower on average.
31225 The
<function>suppress_redundant_updates_trigger
</function> function can be
31226 added to a table like this:
31228 CREATE TRIGGER z_min_update
31229 BEFORE UPDATE ON tablename
31230 FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger();
31232 In most cases, you need to fire this trigger last for each row, so that
31233 it does not override other triggers that might wish to alter the row.
31234 Bearing in mind that triggers fire in name order, you would therefore
31235 choose a trigger name that comes after the name of any other trigger
31236 you might have on the table. (Hence the
<quote>z
</quote> prefix in the
31241 <sect1 id=
"functions-event-triggers">
31242 <title>Event Trigger Functions
</title>
31245 <productname>PostgreSQL
</productname> provides these helper functions
31246 to retrieve information from event triggers.
31250 For more information about event triggers,
31251 see
<xref linkend=
"event-triggers"/>.
31254 <sect2 id=
"pg-event-trigger-ddl-command-end-functions">
31255 <title>Capturing Changes at Command End
</title>
31258 <primary>pg_event_trigger_ddl_commands
</primary>
31262 <function>pg_event_trigger_ddl_commands
</function> ()
<returnvalue>setof record
</returnvalue>
31266 <function>pg_event_trigger_ddl_commands
</function> returns a list of
31267 <acronym>DDL
</acronym> commands executed by each user action,
31268 when invoked in a function attached to a
31269 <literal>ddl_command_end
</literal> event trigger. If called in any other
31270 context, an error is raised.
31271 <function>pg_event_trigger_ddl_commands
</function> returns one row for each
31272 base command executed; some commands that are a single SQL sentence
31273 may return more than one row. This function returns the following
31280 <entry>Name
</entry>
31281 <entry>Type
</entry>
31282 <entry>Description
</entry>
31288 <entry><literal>classid
</literal></entry>
31289 <entry><type>oid
</type></entry>
31290 <entry>OID of catalog the object belongs in
</entry>
31293 <entry><literal>objid
</literal></entry>
31294 <entry><type>oid
</type></entry>
31295 <entry>OID of the object itself
</entry>
31298 <entry><literal>objsubid
</literal></entry>
31299 <entry><type>integer
</type></entry>
31300 <entry>Sub-object ID (e.g., attribute number for a column)
</entry>
31303 <entry><literal>command_tag
</literal></entry>
31304 <entry><type>text
</type></entry>
31305 <entry>Command tag
</entry>
31308 <entry><literal>object_type
</literal></entry>
31309 <entry><type>text
</type></entry>
31310 <entry>Type of the object
</entry>
31313 <entry><literal>schema_name
</literal></entry>
31314 <entry><type>text
</type></entry>
31316 Name of the schema the object belongs in, if any; otherwise
<literal>NULL
</literal>.
31317 No quoting is applied.
31321 <entry><literal>object_identity
</literal></entry>
31322 <entry><type>text
</type></entry>
31324 Text rendering of the object identity, schema-qualified. Each
31325 identifier included in the identity is quoted if necessary.
31329 <entry><literal>in_extension
</literal></entry>
31330 <entry><type>boolean
</type></entry>
31331 <entry>True if the command is part of an extension script
</entry>
31334 <entry><literal>command
</literal></entry>
31335 <entry><type>pg_ddl_command
</type></entry>
31337 A complete representation of the command, in internal format.
31338 This cannot be output directly, but it can be passed to other
31339 functions to obtain different pieces of information about the
31349 <sect2 id=
"pg-event-trigger-sql-drop-functions">
31350 <title>Processing Objects Dropped by a DDL Command
</title>
31353 <primary>pg_event_trigger_dropped_objects
</primary>
31357 <function>pg_event_trigger_dropped_objects
</function> ()
<returnvalue>setof record
</returnvalue>
31361 <function>pg_event_trigger_dropped_objects
</function> returns a list of all objects
31362 dropped by the command in whose
<literal>sql_drop
</literal> event it is called.
31363 If called in any other context, an error is raised.
31364 This function returns the following columns:
31370 <entry>Name
</entry>
31371 <entry>Type
</entry>
31372 <entry>Description
</entry>
31378 <entry><literal>classid
</literal></entry>
31379 <entry><type>oid
</type></entry>
31380 <entry>OID of catalog the object belonged in
</entry>
31383 <entry><literal>objid
</literal></entry>
31384 <entry><type>oid
</type></entry>
31385 <entry>OID of the object itself
</entry>
31388 <entry><literal>objsubid
</literal></entry>
31389 <entry><type>integer
</type></entry>
31390 <entry>Sub-object ID (e.g., attribute number for a column)
</entry>
31393 <entry><literal>original
</literal></entry>
31394 <entry><type>boolean
</type></entry>
31395 <entry>True if this was one of the root object(s) of the deletion
</entry>
31398 <entry><literal>normal
</literal></entry>
31399 <entry><type>boolean
</type></entry>
31401 True if there was a normal dependency relationship
31402 in the dependency graph leading to this object
31406 <entry><literal>is_temporary
</literal></entry>
31407 <entry><type>boolean
</type></entry>
31409 True if this was a temporary object
31413 <entry><literal>object_type
</literal></entry>
31414 <entry><type>text
</type></entry>
31415 <entry>Type of the object
</entry>
31418 <entry><literal>schema_name
</literal></entry>
31419 <entry><type>text
</type></entry>
31421 Name of the schema the object belonged in, if any; otherwise
<literal>NULL
</literal>.
31422 No quoting is applied.
31426 <entry><literal>object_name
</literal></entry>
31427 <entry><type>text
</type></entry>
31429 Name of the object, if the combination of schema and name can be
31430 used as a unique identifier for the object; otherwise
<literal>NULL
</literal>.
31431 No quoting is applied, and name is never schema-qualified.
31435 <entry><literal>object_identity
</literal></entry>
31436 <entry><type>text
</type></entry>
31438 Text rendering of the object identity, schema-qualified. Each
31439 identifier included in the identity is quoted if necessary.
31443 <entry><literal>address_names
</literal></entry>
31444 <entry><type>text[]
</type></entry>
31446 An array that, together with
<literal>object_type
</literal> and
31447 <literal>address_args
</literal>, can be used by
31448 the
<function>pg_get_object_address
</function> function to
31449 recreate the object address in a remote server containing an
31450 identically named object of the same kind.
31454 <entry><literal>address_args
</literal></entry>
31455 <entry><type>text[]
</type></entry>
31457 Complement for
<literal>address_names
</literal>
31466 The
<function>pg_event_trigger_dropped_objects
</function> function can be used
31467 in an event trigger like this:
31469 CREATE FUNCTION test_event_trigger_for_drops()
31470 RETURNS event_trigger LANGUAGE plpgsql AS $$
31474 FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
31476 RAISE NOTICE '% dropped object: % %.% %',
31481 obj.object_identity;
31485 CREATE EVENT TRIGGER test_event_trigger_for_drops
31487 EXECUTE FUNCTION test_event_trigger_for_drops();
31492 <sect2 id=
"pg-event-trigger-table-rewrite-functions">
31493 <title>Handling a Table Rewrite Event
</title>
31496 The functions shown in
31497 <xref linkend=
"functions-event-trigger-table-rewrite"/>
31498 provide information about a table for which a
31499 <literal>table_rewrite
</literal> event has just been called.
31500 If called in any other context, an error is raised.
31503 <table id=
"functions-event-trigger-table-rewrite">
31504 <title>Table Rewrite Information Functions
</title>
31508 <entry role=
"func_table_entry"><para role=
"func_signature">
31519 <entry role=
"func_table_entry"><para role=
"func_signature">
31521 <primary>pg_event_trigger_table_rewrite_oid
</primary>
31523 <function>pg_event_trigger_table_rewrite_oid
</function> ()
31524 <returnvalue>oid
</returnvalue>
31527 Returns the OID of the table about to be rewritten.
31532 <entry role=
"func_table_entry"><para role=
"func_signature">
31534 <primary>pg_event_trigger_table_rewrite_reason
</primary>
31536 <function>pg_event_trigger_table_rewrite_reason
</function> ()
31537 <returnvalue>integer
</returnvalue>
31540 Returns a code explaining the reason(s) for rewriting. The value is
31541 a bitmap built from the following values:
<literal>1</literal>
31542 (the table has changed its persistence),
<literal>2</literal>
31543 (default value of a column has changed),
<literal>4</literal>
31544 (a column has a new data type) and
<literal>8</literal>
31545 (the table access method has changed).
31553 These functions can be used in an event trigger like this:
31555 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
31556 RETURNS event_trigger
31557 LANGUAGE plpgsql AS
31560 RAISE NOTICE 'rewriting table % for reason %',
31561 pg_event_trigger_table_rewrite_oid()::regclass,
31562 pg_event_trigger_table_rewrite_reason();
31566 CREATE EVENT TRIGGER test_table_rewrite_oid
31568 EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
31574 <sect1 id=
"functions-statistics">
31575 <title>Statistics Information Functions
</title>
31577 <indexterm zone=
"functions-statistics">
31578 <primary>function
</primary>
31579 <secondary>statistics
</secondary>
31583 <productname>PostgreSQL
</productname> provides a function to inspect complex
31584 statistics defined using the
<command>CREATE STATISTICS
</command> command.
31587 <sect2 id=
"functions-statistics-mcv">
31588 <title>Inspecting MCV Lists
</title>
31591 <primary>pg_mcv_list_items
</primary>
31595 <function>pg_mcv_list_items
</function> (
<type>pg_mcv_list
</type> )
<returnvalue>setof record
</returnvalue>
31599 <function>pg_mcv_list_items
</function> returns a set of records describing
31600 all items stored in a multi-column
<acronym>MCV
</acronym> list. It
31601 returns the following columns:
31607 <entry>Name
</entry>
31608 <entry>Type
</entry>
31609 <entry>Description
</entry>
31615 <entry><literal>index
</literal></entry>
31616 <entry><type>integer
</type></entry>
31617 <entry>index of the item in the
<acronym>MCV
</acronym> list
</entry>
31620 <entry><literal>values
</literal></entry>
31621 <entry><type>text[]
</type></entry>
31622 <entry>values stored in the MCV item
</entry>
31625 <entry><literal>nulls
</literal></entry>
31626 <entry><type>boolean[]
</type></entry>
31627 <entry>flags identifying
<literal>NULL
</literal> values
</entry>
31630 <entry><literal>frequency
</literal></entry>
31631 <entry><type>double precision
</type></entry>
31632 <entry>frequency of this
<acronym>MCV
</acronym> item
</entry>
31635 <entry><literal>base_frequency
</literal></entry>
31636 <entry><type>double precision
</type></entry>
31637 <entry>base frequency of this
<acronym>MCV
</acronym> item
</entry>
31645 The
<function>pg_mcv_list_items
</function> function can be used like this:
31648 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
31649 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
31652 Values of the
<type>pg_mcv_list
</type> type can be obtained only from the
31653 <structname>pg_statistic_ext_data
</structname>.
<structfield>stxdmcv
</structfield>