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. In some cases, it may be preferable to
722 write
<replaceable>row
</replaceable> <literal>IS DISTINCT FROM NULL
</literal>
723 or
<replaceable>row
</replaceable> <literal>IS NOT DISTINCT FROM NULL
</literal>,
724 which will simply check whether the overall row value is null without any
725 additional tests on the row fields.
730 <primary>IS TRUE
</primary>
733 <primary>IS NOT TRUE
</primary>
736 <primary>IS FALSE
</primary>
739 <primary>IS NOT FALSE
</primary>
742 <primary>IS UNKNOWN
</primary>
745 <primary>IS NOT UNKNOWN
</primary>
747 Boolean values can also be tested using the predicates
749 <replaceable>boolean_expression
</replaceable> IS TRUE
750 <replaceable>boolean_expression
</replaceable> IS NOT TRUE
751 <replaceable>boolean_expression
</replaceable> IS FALSE
752 <replaceable>boolean_expression
</replaceable> IS NOT FALSE
753 <replaceable>boolean_expression
</replaceable> IS UNKNOWN
754 <replaceable>boolean_expression
</replaceable> IS NOT UNKNOWN
756 These will always return true or false, never a null value, even when the
758 A null input is treated as the logical value
<quote>unknown
</quote>.
759 Notice that
<literal>IS UNKNOWN
</literal> and
<literal>IS NOT UNKNOWN
</literal> are
760 effectively the same as
<literal>IS NULL
</literal> and
761 <literal>IS NOT NULL
</literal>, respectively, except that the input
762 expression must be of Boolean type.
766 Some comparison-related functions are also available, as shown in
<xref
767 linkend=
"functions-comparison-func-table"/>.
770 <table id=
"functions-comparison-func-table">
771 <title>Comparison Functions
</title>
775 <entry role=
"func_table_entry"><para role=
"func_signature">
789 <entry role=
"func_table_entry"><para role=
"func_signature">
791 <primary>num_nonnulls
</primary>
793 <function>num_nonnulls
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
794 <returnvalue>integer
</returnvalue>
797 Returns the number of non-null arguments.
800 <literal>num_nonnulls(
1, NULL,
2)
</literal>
801 <returnvalue>2</returnvalue>
805 <entry role=
"func_table_entry"><para role=
"func_signature">
807 <primary>num_nulls
</primary>
809 <function>num_nulls
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
810 <returnvalue>integer
</returnvalue>
813 Returns the number of null arguments.
816 <literal>num_nulls(
1, NULL,
2)
</literal>
817 <returnvalue>1</returnvalue>
826 <sect1 id=
"functions-math">
827 <title>Mathematical Functions and Operators
</title>
830 Mathematical operators are provided for many
831 <productname>PostgreSQL
</productname> types. For types without
832 standard mathematical conventions
833 (e.g., date/time types) we
834 describe the actual behavior in subsequent sections.
838 <xref linkend=
"functions-math-op-table"/> shows the mathematical
839 operators that are available for the standard numeric types.
840 Unless otherwise noted, operators shown as
841 accepting
<replaceable>numeric_type
</replaceable> are available for all
842 the types
<type>smallint
</type>,
<type>integer
</type>,
843 <type>bigint
</type>,
<type>numeric
</type>,
<type>real
</type>,
844 and
<type>double precision
</type>.
845 Operators shown as accepting
<replaceable>integral_type
</replaceable>
846 are available for the types
<type>smallint
</type>,
<type>integer
</type>,
847 and
<type>bigint
</type>.
848 Except where noted, each form of an operator returns the same data type
849 as its argument(s). Calls involving multiple argument data types, such
850 as
<type>integer
</type> <literal>+
</literal> <type>numeric
</type>,
851 are resolved by using the type appearing later in these lists.
854 <table id=
"functions-math-op-table">
855 <title>Mathematical Operators
</title>
860 <entry role=
"func_table_entry"><para role=
"func_signature">
874 <entry role=
"func_table_entry"><para role=
"func_signature">
875 <replaceable>numeric_type
</replaceable> <literal>+
</literal> <replaceable>numeric_type
</replaceable>
876 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
882 <literal>2 +
3</literal>
883 <returnvalue>5</returnvalue>
888 <entry role=
"func_table_entry"><para role=
"func_signature">
889 <literal>+
</literal> <replaceable>numeric_type
</replaceable>
890 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
893 Unary plus (no operation)
896 <literal>+
3.5</literal>
897 <returnvalue>3.5</returnvalue>
902 <entry role=
"func_table_entry"><para role=
"func_signature">
903 <replaceable>numeric_type
</replaceable> <literal>-
</literal> <replaceable>numeric_type
</replaceable>
904 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
910 <literal>2 -
3</literal>
911 <returnvalue>-
1</returnvalue>
916 <entry role=
"func_table_entry"><para role=
"func_signature">
917 <literal>-
</literal> <replaceable>numeric_type
</replaceable>
918 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
924 <literal>- (-
4)
</literal>
925 <returnvalue>4</returnvalue>
930 <entry role=
"func_table_entry"><para role=
"func_signature">
931 <replaceable>numeric_type
</replaceable> <literal>*
</literal> <replaceable>numeric_type
</replaceable>
932 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
938 <literal>2 *
3</literal>
939 <returnvalue>6</returnvalue>
944 <entry role=
"func_table_entry"><para role=
"func_signature">
945 <replaceable>numeric_type
</replaceable> <literal>/
</literal> <replaceable>numeric_type
</replaceable>
946 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
949 Division (for integral types, division truncates the result towards
953 <literal>5.0 /
2</literal>
954 <returnvalue>2.5000000000000000</returnvalue>
957 <literal>5 /
2</literal>
958 <returnvalue>2</returnvalue>
961 <literal>(-
5) /
2</literal>
962 <returnvalue>-
2</returnvalue>
967 <entry role=
"func_table_entry"><para role=
"func_signature">
968 <replaceable>numeric_type
</replaceable> <literal>%
</literal> <replaceable>numeric_type
</replaceable>
969 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
972 Modulo (remainder); available for
<type>smallint
</type>,
973 <type>integer
</type>,
<type>bigint
</type>, and
<type>numeric
</type>
976 <literal>5 %
4</literal>
977 <returnvalue>1</returnvalue>
982 <entry role=
"func_table_entry"><para role=
"func_signature">
983 <type>numeric
</type> <literal>^
</literal> <type>numeric
</type>
984 <returnvalue>numeric
</returnvalue>
986 <para role=
"func_signature">
987 <type>double precision
</type> <literal>^
</literal> <type>double precision
</type>
988 <returnvalue>double precision
</returnvalue>
994 <literal>2 ^
3</literal>
995 <returnvalue>8</returnvalue>
998 Unlike typical mathematical practice, multiple uses of
999 <literal>^
</literal> will associate left to right by default:
1002 <literal>2 ^
3 ^
3</literal>
1003 <returnvalue>512</returnvalue>
1006 <literal>2 ^ (
3 ^
3)
</literal>
1007 <returnvalue>134217728</returnvalue>
1012 <entry role=
"func_table_entry"><para role=
"func_signature">
1013 <literal>|/
</literal> <type>double precision
</type>
1014 <returnvalue>double precision
</returnvalue>
1020 <literal>|/
25.0</literal>
1021 <returnvalue>5</returnvalue>
1026 <entry role=
"func_table_entry"><para role=
"func_signature">
1027 <literal>||/
</literal> <type>double precision
</type>
1028 <returnvalue>double precision
</returnvalue>
1034 <literal>||/
64.0</literal>
1035 <returnvalue>4</returnvalue>
1040 <entry role=
"func_table_entry"><para role=
"func_signature">
1041 <literal>@
</literal> <replaceable>numeric_type
</replaceable>
1042 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1048 <literal>@ -
5.0</literal>
1049 <returnvalue>5.0</returnvalue>
1054 <entry role=
"func_table_entry"><para role=
"func_signature">
1055 <replaceable>integral_type
</replaceable> <literal>&</literal> <replaceable>integral_type
</replaceable>
1056 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1062 <literal>91 & 15</literal>
1063 <returnvalue>11</returnvalue>
1068 <entry role=
"func_table_entry"><para role=
"func_signature">
1069 <replaceable>integral_type
</replaceable> <literal>|
</literal> <replaceable>integral_type
</replaceable>
1070 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1076 <literal>32 |
3</literal>
1077 <returnvalue>35</returnvalue>
1082 <entry role=
"func_table_entry"><para role=
"func_signature">
1083 <replaceable>integral_type
</replaceable> <literal>#
</literal> <replaceable>integral_type
</replaceable>
1084 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1087 Bitwise exclusive OR
1090 <literal>17 #
5</literal>
1091 <returnvalue>20</returnvalue>
1096 <entry role=
"func_table_entry"><para role=
"func_signature">
1097 <literal>~
</literal> <replaceable>integral_type
</replaceable>
1098 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1104 <literal>~
1</literal>
1105 <returnvalue>-
2</returnvalue>
1110 <entry role=
"func_table_entry"><para role=
"func_signature">
1111 <replaceable>integral_type
</replaceable> <literal><<</literal> <type>integer
</type>
1112 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1118 <literal>1 << 4</literal>
1119 <returnvalue>16</returnvalue>
1124 <entry role=
"func_table_entry"><para role=
"func_signature">
1125 <replaceable>integral_type
</replaceable> <literal>>></literal> <type>integer
</type>
1126 <returnvalue><replaceable>integral_type
</replaceable></returnvalue>
1132 <literal>8 >> 2</literal>
1133 <returnvalue>2</returnvalue>
1142 <xref linkend=
"functions-math-func-table"/> shows the available
1143 mathematical functions.
1144 Many of these functions are provided in multiple forms with different
1146 Except where noted, any given form of a function returns the same
1147 data type as its argument(s); cross-type cases are resolved in the
1148 same way as explained above for operators.
1149 The functions working with
<type>double precision
</type> data are mostly
1150 implemented on top of the host system's C library; accuracy and behavior in
1151 boundary cases can therefore vary depending on the host system.
1154 <table id=
"functions-math-func-table">
1155 <title>Mathematical Functions
</title>
1159 <entry role=
"func_table_entry"><para role=
"func_signature">
1173 <entry role=
"func_table_entry"><para role=
"func_signature">
1175 <primary>abs
</primary>
1177 <function>abs
</function> (
<replaceable>numeric_type
</replaceable> )
1178 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1184 <literal>abs(-
17.4)
</literal>
1185 <returnvalue>17.4</returnvalue>
1190 <entry role=
"func_table_entry"><para role=
"func_signature">
1192 <primary>cbrt
</primary>
1194 <function>cbrt
</function> (
<type>double precision
</type> )
1195 <returnvalue>double precision
</returnvalue>
1201 <literal>cbrt(
64.0)
</literal>
1202 <returnvalue>4</returnvalue>
1207 <entry role=
"func_table_entry"><para role=
"func_signature">
1209 <primary>ceil
</primary>
1211 <function>ceil
</function> (
<type>numeric
</type> )
1212 <returnvalue>numeric
</returnvalue>
1214 <para role=
"func_signature">
1215 <function>ceil
</function> (
<type>double precision
</type> )
1216 <returnvalue>double precision
</returnvalue>
1219 Nearest integer greater than or equal to argument
1222 <literal>ceil(
42.2)
</literal>
1223 <returnvalue>43</returnvalue>
1226 <literal>ceil(-
42.8)
</literal>
1227 <returnvalue>-
42</returnvalue>
1232 <entry role=
"func_table_entry"><para role=
"func_signature">
1234 <primary>ceiling
</primary>
1236 <function>ceiling
</function> (
<type>numeric
</type> )
1237 <returnvalue>numeric
</returnvalue>
1239 <para role=
"func_signature">
1240 <function>ceiling
</function> (
<type>double precision
</type> )
1241 <returnvalue>double precision
</returnvalue>
1244 Nearest integer greater than or equal to argument (same
1245 as
<function>ceil
</function>)
1248 <literal>ceiling(
95.3)
</literal>
1249 <returnvalue>96</returnvalue>
1254 <entry role=
"func_table_entry"><para role=
"func_signature">
1256 <primary>degrees
</primary>
1258 <function>degrees
</function> (
<type>double precision
</type> )
1259 <returnvalue>double precision
</returnvalue>
1262 Converts radians to degrees
1265 <literal>degrees(
0.5)
</literal>
1266 <returnvalue>28.64788975654116</returnvalue>
1271 <entry role=
"func_table_entry"><para role=
"func_signature">
1273 <primary>div
</primary>
1275 <function>div
</function> (
<parameter>y
</parameter> <type>numeric
</type>,
1276 <parameter>x
</parameter> <type>numeric
</type> )
1277 <returnvalue>numeric
</returnvalue>
1280 Integer quotient of
<parameter>y
</parameter>/
<parameter>x
</parameter>
1281 (truncates towards zero)
1284 <literal>div(
9,
4)
</literal>
1285 <returnvalue>2</returnvalue>
1290 <entry role=
"func_table_entry"><para role=
"func_signature">
1292 <primary>erf
</primary>
1294 <function>erf
</function> (
<type>double precision
</type> )
1295 <returnvalue>double precision
</returnvalue>
1301 <literal>erf(
1.0)
</literal>
1302 <returnvalue>0.8427007929497149</returnvalue>
1307 <entry role=
"func_table_entry"><para role=
"func_signature">
1309 <primary>erfc
</primary>
1311 <function>erfc
</function> (
<type>double precision
</type> )
1312 <returnvalue>double precision
</returnvalue>
1315 Complementary error function (
<literal>1 - erf(x)
</literal>, without
1316 loss of precision for large inputs)
1319 <literal>erfc(
1.0)
</literal>
1320 <returnvalue>0.15729920705028513</returnvalue>
1325 <entry role=
"func_table_entry"><para role=
"func_signature">
1327 <primary>exp
</primary>
1329 <function>exp
</function> (
<type>numeric
</type> )
1330 <returnvalue>numeric
</returnvalue>
1332 <para role=
"func_signature">
1333 <function>exp
</function> (
<type>double precision
</type> )
1334 <returnvalue>double precision
</returnvalue>
1337 Exponential (
<literal>e
</literal> raised to the given power)
1340 <literal>exp(
1.0)
</literal>
1341 <returnvalue>2.7182818284590452</returnvalue>
1346 <entry role=
"func_table_entry"><para role=
"func_signature">
1347 <indexterm id=
"function-factorial">
1348 <primary>factorial
</primary>
1350 <function>factorial
</function> (
<type>bigint
</type> )
1351 <returnvalue>numeric
</returnvalue>
1357 <literal>factorial(
5)
</literal>
1358 <returnvalue>120</returnvalue>
1363 <entry role=
"func_table_entry"><para role=
"func_signature">
1365 <primary>floor
</primary>
1367 <function>floor
</function> (
<type>numeric
</type> )
1368 <returnvalue>numeric
</returnvalue>
1370 <para role=
"func_signature">
1371 <function>floor
</function> (
<type>double precision
</type> )
1372 <returnvalue>double precision
</returnvalue>
1375 Nearest integer less than or equal to argument
1378 <literal>floor(
42.8)
</literal>
1379 <returnvalue>42</returnvalue>
1382 <literal>floor(-
42.8)
</literal>
1383 <returnvalue>-
43</returnvalue>
1388 <entry role=
"func_table_entry"><para role=
"func_signature">
1390 <primary>gcd
</primary>
1392 <function>gcd
</function> (
<replaceable>numeric_type
</replaceable>,
<replaceable>numeric_type
</replaceable> )
1393 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1396 Greatest common divisor (the largest positive number that divides both
1397 inputs with no remainder); returns
<literal>0</literal> if both inputs
1398 are zero; available for
<type>integer
</type>,
<type>bigint
</type>,
1399 and
<type>numeric
</type>
1402 <literal>gcd(
1071,
462)
</literal>
1403 <returnvalue>21</returnvalue>
1408 <entry role=
"func_table_entry"><para role=
"func_signature">
1410 <primary>lcm
</primary>
1412 <function>lcm
</function> (
<replaceable>numeric_type
</replaceable>,
<replaceable>numeric_type
</replaceable> )
1413 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1416 Least common multiple (the smallest strictly positive number that is
1417 an integral multiple of both inputs); returns
<literal>0</literal> if
1418 either input is zero; available for
<type>integer
</type>,
1419 <type>bigint
</type>, and
<type>numeric
</type>
1422 <literal>lcm(
1071,
462)
</literal>
1423 <returnvalue>23562</returnvalue>
1428 <entry role=
"func_table_entry"><para role=
"func_signature">
1430 <primary>ln
</primary>
1432 <function>ln
</function> (
<type>numeric
</type> )
1433 <returnvalue>numeric
</returnvalue>
1435 <para role=
"func_signature">
1436 <function>ln
</function> (
<type>double precision
</type> )
1437 <returnvalue>double precision
</returnvalue>
1443 <literal>ln(
2.0)
</literal>
1444 <returnvalue>0.6931471805599453</returnvalue>
1449 <entry role=
"func_table_entry"><para role=
"func_signature">
1451 <primary>log
</primary>
1453 <function>log
</function> (
<type>numeric
</type> )
1454 <returnvalue>numeric
</returnvalue>
1456 <para role=
"func_signature">
1457 <function>log
</function> (
<type>double precision
</type> )
1458 <returnvalue>double precision
</returnvalue>
1464 <literal>log(
100)
</literal>
1465 <returnvalue>2</returnvalue>
1470 <entry role=
"func_table_entry"><para role=
"func_signature">
1472 <primary>log10
</primary>
1474 <function>log10
</function> (
<type>numeric
</type> )
1475 <returnvalue>numeric
</returnvalue>
1477 <para role=
"func_signature">
1478 <function>log10
</function> (
<type>double precision
</type> )
1479 <returnvalue>double precision
</returnvalue>
1482 Base
10 logarithm (same as
<function>log
</function>)
1485 <literal>log10(
1000)
</literal>
1486 <returnvalue>3</returnvalue>
1491 <entry role=
"func_table_entry"><para role=
"func_signature">
1492 <function>log
</function> (
<parameter>b
</parameter> <type>numeric
</type>,
1493 <parameter>x
</parameter> <type>numeric
</type> )
1494 <returnvalue>numeric
</returnvalue>
1497 Logarithm of
<parameter>x
</parameter> to base
<parameter>b
</parameter>
1500 <literal>log(
2.0,
64.0)
</literal>
1501 <returnvalue>6.0000000000000000</returnvalue>
1506 <entry role=
"func_table_entry"><para role=
"func_signature">
1508 <primary>min_scale
</primary>
1510 <function>min_scale
</function> (
<type>numeric
</type> )
1511 <returnvalue>integer
</returnvalue>
1514 Minimum scale (number of fractional decimal digits) needed
1515 to represent the supplied value precisely
1518 <literal>min_scale(
8.4100)
</literal>
1519 <returnvalue>2</returnvalue>
1524 <entry role=
"func_table_entry"><para role=
"func_signature">
1526 <primary>mod
</primary>
1528 <function>mod
</function> (
<parameter>y
</parameter> <replaceable>numeric_type
</replaceable>,
1529 <parameter>x
</parameter> <replaceable>numeric_type
</replaceable> )
1530 <returnvalue><replaceable>numeric_type
</replaceable></returnvalue>
1533 Remainder of
<parameter>y
</parameter>/
<parameter>x
</parameter>;
1534 available for
<type>smallint
</type>,
<type>integer
</type>,
1535 <type>bigint
</type>, and
<type>numeric
</type>
1538 <literal>mod(
9,
4)
</literal>
1539 <returnvalue>1</returnvalue>
1544 <entry role=
"func_table_entry"><para role=
"func_signature">
1546 <primary>pi
</primary>
1548 <function>pi
</function> ( )
1549 <returnvalue>double precision
</returnvalue>
1552 Approximate value of
<phrase role=
"symbol_font">π</phrase>
1555 <literal>pi()
</literal>
1556 <returnvalue>3.141592653589793</returnvalue>
1561 <entry role=
"func_table_entry"><para role=
"func_signature">
1563 <primary>power
</primary>
1565 <function>power
</function> (
<parameter>a
</parameter> <type>numeric
</type>,
1566 <parameter>b
</parameter> <type>numeric
</type> )
1567 <returnvalue>numeric
</returnvalue>
1569 <para role=
"func_signature">
1570 <function>power
</function> (
<parameter>a
</parameter> <type>double precision
</type>,
1571 <parameter>b
</parameter> <type>double precision
</type> )
1572 <returnvalue>double precision
</returnvalue>
1575 <parameter>a
</parameter> raised to the power of
<parameter>b
</parameter>
1578 <literal>power(
9,
3)
</literal>
1579 <returnvalue>729</returnvalue>
1584 <entry role=
"func_table_entry"><para role=
"func_signature">
1586 <primary>radians
</primary>
1588 <function>radians
</function> (
<type>double precision
</type> )
1589 <returnvalue>double precision
</returnvalue>
1592 Converts degrees to radians
1595 <literal>radians(
45.0)
</literal>
1596 <returnvalue>0.7853981633974483</returnvalue>
1601 <entry role=
"func_table_entry"><para role=
"func_signature">
1603 <primary>round
</primary>
1605 <function>round
</function> (
<type>numeric
</type> )
1606 <returnvalue>numeric
</returnvalue>
1608 <para role=
"func_signature">
1609 <function>round
</function> (
<type>double precision
</type> )
1610 <returnvalue>double precision
</returnvalue>
1613 Rounds to nearest integer. For
<type>numeric
</type>, ties are
1614 broken by rounding away from zero. For
<type>double precision
</type>,
1615 the tie-breaking behavior is platform dependent, but
1616 <quote>round to nearest even
</quote> is the most common rule.
1619 <literal>round(
42.4)
</literal>
1620 <returnvalue>42</returnvalue>
1625 <entry role=
"func_table_entry"><para role=
"func_signature">
1626 <function>round
</function> (
<parameter>v
</parameter> <type>numeric
</type>,
<parameter>s
</parameter> <type>integer
</type> )
1627 <returnvalue>numeric
</returnvalue>
1630 Rounds
<parameter>v
</parameter> to
<parameter>s
</parameter> decimal
1631 places. Ties are broken by rounding away from zero.
1634 <literal>round(
42.4382,
2)
</literal>
1635 <returnvalue>42.44</returnvalue>
1638 <literal>round(
1234.56, -
1)
</literal>
1639 <returnvalue>1230</returnvalue>
1644 <entry role=
"func_table_entry"><para role=
"func_signature">
1646 <primary>scale
</primary>
1648 <function>scale
</function> (
<type>numeric
</type> )
1649 <returnvalue>integer
</returnvalue>
1652 Scale of the argument (the number of decimal digits in the fractional part)
1655 <literal>scale(
8.4100)
</literal>
1656 <returnvalue>4</returnvalue>
1661 <entry role=
"func_table_entry"><para role=
"func_signature">
1663 <primary>sign
</primary>
1665 <function>sign
</function> (
<type>numeric
</type> )
1666 <returnvalue>numeric
</returnvalue>
1668 <para role=
"func_signature">
1669 <function>sign
</function> (
<type>double precision
</type> )
1670 <returnvalue>double precision
</returnvalue>
1673 Sign of the argument (-
1,
0, or +
1)
1676 <literal>sign(-
8.4)
</literal>
1677 <returnvalue>-
1</returnvalue>
1682 <entry role=
"func_table_entry"><para role=
"func_signature">
1684 <primary>sqrt
</primary>
1686 <function>sqrt
</function> (
<type>numeric
</type> )
1687 <returnvalue>numeric
</returnvalue>
1689 <para role=
"func_signature">
1690 <function>sqrt
</function> (
<type>double precision
</type> )
1691 <returnvalue>double precision
</returnvalue>
1697 <literal>sqrt(
2)
</literal>
1698 <returnvalue>1.4142135623730951</returnvalue>
1703 <entry role=
"func_table_entry"><para role=
"func_signature">
1705 <primary>trim_scale
</primary>
1707 <function>trim_scale
</function> (
<type>numeric
</type> )
1708 <returnvalue>numeric
</returnvalue>
1711 Reduces the value's scale (number of fractional decimal digits) by
1712 removing trailing zeroes
1715 <literal>trim_scale(
8.4100)
</literal>
1716 <returnvalue>8.41</returnvalue>
1721 <entry role=
"func_table_entry"><para role=
"func_signature">
1723 <primary>trunc
</primary>
1725 <function>trunc
</function> (
<type>numeric
</type> )
1726 <returnvalue>numeric
</returnvalue>
1728 <para role=
"func_signature">
1729 <function>trunc
</function> (
<type>double precision
</type> )
1730 <returnvalue>double precision
</returnvalue>
1733 Truncates to integer (towards zero)
1736 <literal>trunc(
42.8)
</literal>
1737 <returnvalue>42</returnvalue>
1740 <literal>trunc(-
42.8)
</literal>
1741 <returnvalue>-
42</returnvalue>
1746 <entry role=
"func_table_entry"><para role=
"func_signature">
1747 <function>trunc
</function> (
<parameter>v
</parameter> <type>numeric
</type>,
<parameter>s
</parameter> <type>integer
</type> )
1748 <returnvalue>numeric
</returnvalue>
1751 Truncates
<parameter>v
</parameter> to
<parameter>s
</parameter>
1755 <literal>trunc(
42.4382,
2)
</literal>
1756 <returnvalue>42.43</returnvalue>
1761 <entry role=
"func_table_entry"><para role=
"func_signature">
1763 <primary>width_bucket
</primary>
1765 <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> )
1766 <returnvalue>integer
</returnvalue>
1768 <para role=
"func_signature">
1769 <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> )
1770 <returnvalue>integer
</returnvalue>
1773 Returns the number of the bucket in
1774 which
<parameter>operand
</parameter> falls in a histogram
1775 having
<parameter>count
</parameter> equal-width buckets spanning the
1776 range
<parameter>low
</parameter> to
<parameter>high
</parameter>.
1777 Returns
<literal>0</literal>
1778 or
<literal><parameter>count
</parameter>+
1</literal> for an input
1782 <literal>width_bucket(
5.35,
0.024,
10.06,
5)
</literal>
1783 <returnvalue>3</returnvalue>
1788 <entry role=
"func_table_entry"><para role=
"func_signature">
1789 <function>width_bucket
</function> (
<parameter>operand
</parameter> <type>anycompatible
</type>,
<parameter>thresholds
</parameter> <type>anycompatiblearray
</type> )
1790 <returnvalue>integer
</returnvalue>
1793 Returns the number of the bucket in
1794 which
<parameter>operand
</parameter> falls given an array listing the
1795 lower bounds of the buckets. Returns
<literal>0</literal> for an
1796 input less than the first lower
1797 bound.
<parameter>operand
</parameter> and the array elements can be
1798 of any type having standard comparison operators.
1799 The
<parameter>thresholds
</parameter> array
<emphasis>must be
1800 sorted
</emphasis>, smallest first, or unexpected results will be
1804 <literal>width_bucket(now(), array['yesterday', 'today', 'tomorrow']::timestamptz[])
</literal>
1805 <returnvalue>2</returnvalue>
1813 <xref linkend=
"functions-math-random-table"/> shows functions for
1814 generating random numbers.
1817 <table id=
"functions-math-random-table">
1818 <title>Random Functions
</title>
1823 <entry role=
"func_table_entry"><para role=
"func_signature">
1837 <entry role=
"func_table_entry"><para role=
"func_signature">
1839 <primary>random
</primary>
1841 <function>random
</function> ( )
1842 <returnvalue>double precision
</returnvalue>
1845 Returns a random value in the range
0.0 <= x
< 1.0
1848 <literal>random()
</literal>
1849 <returnvalue>0.897124072839091</returnvalue>
1854 <entry role=
"func_table_entry"><para role=
"func_signature">
1856 <primary>random_normal
</primary>
1859 <function>random_normal
</function> (
1860 <optional> <parameter>mean
</parameter> <type>double precision
</type>
1861 <optional>,
<parameter>stddev
</parameter> <type>double precision
</type> </optional></optional> )
1862 <returnvalue>double precision
</returnvalue>
1865 Returns a random value from the normal distribution with the given
1866 parameters;
<parameter>mean
</parameter> defaults to
0.0
1867 and
<parameter>stddev
</parameter> defaults to
1.0
1870 <literal>random_normal(
0.0,
1.0)
</literal>
1871 <returnvalue>0.051285419</returnvalue>
1876 <entry role=
"func_table_entry"><para role=
"func_signature">
1878 <primary>setseed
</primary>
1880 <function>setseed
</function> (
<type>double precision
</type> )
1881 <returnvalue>void
</returnvalue>
1884 Sets the seed for subsequent
<literal>random()
</literal> and
1885 <literal>random_normal()
</literal> calls;
1886 argument must be between -
1.0 and
1.0, inclusive
1889 <literal>setseed(
0.12345)
</literal>
1897 The
<function>random()
</function> function uses a deterministic
1898 pseudo-random number generator.
1899 It is fast but not suitable for cryptographic
1900 applications; see the
<xref linkend=
"pgcrypto"/> module for a more
1902 If
<function>setseed()
</function> is called, the series of results of
1903 subsequent
<function>random()
</function> calls in the current session
1904 can be repeated by re-issuing
<function>setseed()
</function> with the same
1906 Without any prior
<function>setseed()
</function> call in the same
1907 session, the first
<function>random()
</function> call obtains a seed
1908 from a platform-dependent source of random bits.
1909 These remarks hold equally for
<function>random_normal()
</function>.
1913 <xref linkend=
"functions-math-trig-table"/> shows the
1914 available trigonometric functions. Each of these functions comes in
1915 two variants, one that measures angles in radians and one that
1916 measures angles in degrees.
1919 <table id=
"functions-math-trig-table">
1920 <title>Trigonometric Functions
</title>
1925 <entry role=
"func_table_entry"><para role=
"func_signature">
1939 <entry role=
"func_table_entry"><para role=
"func_signature">
1941 <primary>acos
</primary>
1943 <function>acos
</function> (
<type>double precision
</type> )
1944 <returnvalue>double precision
</returnvalue>
1947 Inverse cosine, result in radians
1950 <literal>acos(
1)
</literal>
1951 <returnvalue>0</returnvalue>
1956 <entry role=
"func_table_entry"><para role=
"func_signature">
1958 <primary>acosd
</primary>
1960 <function>acosd
</function> (
<type>double precision
</type> )
1961 <returnvalue>double precision
</returnvalue>
1964 Inverse cosine, result in degrees
1967 <literal>acosd(
0.5)
</literal>
1968 <returnvalue>60</returnvalue>
1973 <entry role=
"func_table_entry"><para role=
"func_signature">
1975 <primary>asin
</primary>
1977 <function>asin
</function> (
<type>double precision
</type> )
1978 <returnvalue>double precision
</returnvalue>
1981 Inverse sine, result in radians
1984 <literal>asin(
1)
</literal>
1985 <returnvalue>1.5707963267948966</returnvalue>
1990 <entry role=
"func_table_entry"><para role=
"func_signature">
1992 <primary>asind
</primary>
1994 <function>asind
</function> (
<type>double precision
</type> )
1995 <returnvalue>double precision
</returnvalue>
1998 Inverse sine, result in degrees
2001 <literal>asind(
0.5)
</literal>
2002 <returnvalue>30</returnvalue>
2007 <entry role=
"func_table_entry"><para role=
"func_signature">
2009 <primary>atan
</primary>
2011 <function>atan
</function> (
<type>double precision
</type> )
2012 <returnvalue>double precision
</returnvalue>
2015 Inverse tangent, result in radians
2018 <literal>atan(
1)
</literal>
2019 <returnvalue>0.7853981633974483</returnvalue>
2024 <entry role=
"func_table_entry"><para role=
"func_signature">
2026 <primary>atand
</primary>
2028 <function>atand
</function> (
<type>double precision
</type> )
2029 <returnvalue>double precision
</returnvalue>
2032 Inverse tangent, result in degrees
2035 <literal>atand(
1)
</literal>
2036 <returnvalue>45</returnvalue>
2041 <entry role=
"func_table_entry"><para role=
"func_signature">
2043 <primary>atan2
</primary>
2045 <function>atan2
</function> (
<parameter>y
</parameter> <type>double precision
</type>,
2046 <parameter>x
</parameter> <type>double precision
</type> )
2047 <returnvalue>double precision
</returnvalue>
2051 <parameter>y
</parameter>/
<parameter>x
</parameter>,
2055 <literal>atan2(
1,
0)
</literal>
2056 <returnvalue>1.5707963267948966</returnvalue>
2061 <entry role=
"func_table_entry"><para role=
"func_signature">
2063 <primary>atan2d
</primary>
2065 <function>atan2d
</function> (
<parameter>y
</parameter> <type>double precision
</type>,
2066 <parameter>x
</parameter> <type>double precision
</type> )
2067 <returnvalue>double precision
</returnvalue>
2071 <parameter>y
</parameter>/
<parameter>x
</parameter>,
2075 <literal>atan2d(
1,
0)
</literal>
2076 <returnvalue>90</returnvalue>
2081 <entry role=
"func_table_entry"><para role=
"func_signature">
2083 <primary>cos
</primary>
2085 <function>cos
</function> (
<type>double precision
</type> )
2086 <returnvalue>double precision
</returnvalue>
2089 Cosine, argument in radians
2092 <literal>cos(
0)
</literal>
2093 <returnvalue>1</returnvalue>
2098 <entry role=
"func_table_entry"><para role=
"func_signature">
2100 <primary>cosd
</primary>
2102 <function>cosd
</function> (
<type>double precision
</type> )
2103 <returnvalue>double precision
</returnvalue>
2106 Cosine, argument in degrees
2109 <literal>cosd(
60)
</literal>
2110 <returnvalue>0.5</returnvalue>
2115 <entry role=
"func_table_entry"><para role=
"func_signature">
2117 <primary>cot
</primary>
2119 <function>cot
</function> (
<type>double precision
</type> )
2120 <returnvalue>double precision
</returnvalue>
2123 Cotangent, argument in radians
2126 <literal>cot(
0.5)
</literal>
2127 <returnvalue>1.830487721712452</returnvalue>
2132 <entry role=
"func_table_entry"><para role=
"func_signature">
2134 <primary>cotd
</primary>
2136 <function>cotd
</function> (
<type>double precision
</type> )
2137 <returnvalue>double precision
</returnvalue>
2140 Cotangent, argument in degrees
2143 <literal>cotd(
45)
</literal>
2144 <returnvalue>1</returnvalue>
2149 <entry role=
"func_table_entry"><para role=
"func_signature">
2151 <primary>sin
</primary>
2153 <function>sin
</function> (
<type>double precision
</type> )
2154 <returnvalue>double precision
</returnvalue>
2157 Sine, argument in radians
2160 <literal>sin(
1)
</literal>
2161 <returnvalue>0.8414709848078965</returnvalue>
2166 <entry role=
"func_table_entry"><para role=
"func_signature">
2168 <primary>sind
</primary>
2170 <function>sind
</function> (
<type>double precision
</type> )
2171 <returnvalue>double precision
</returnvalue>
2174 Sine, argument in degrees
2177 <literal>sind(
30)
</literal>
2178 <returnvalue>0.5</returnvalue>
2183 <entry role=
"func_table_entry"><para role=
"func_signature">
2185 <primary>tan
</primary>
2187 <function>tan
</function> (
<type>double precision
</type> )
2188 <returnvalue>double precision
</returnvalue>
2191 Tangent, argument in radians
2194 <literal>tan(
1)
</literal>
2195 <returnvalue>1.5574077246549023</returnvalue>
2200 <entry role=
"func_table_entry"><para role=
"func_signature">
2202 <primary>tand
</primary>
2204 <function>tand
</function> (
<type>double precision
</type> )
2205 <returnvalue>double precision
</returnvalue>
2208 Tangent, argument in degrees
2211 <literal>tand(
45)
</literal>
2212 <returnvalue>1</returnvalue>
2221 Another way to work with angles measured in degrees is to use the unit
2222 transformation functions
<literal><function>radians()
</function></literal>
2223 and
<literal><function>degrees()
</function></literal> shown earlier.
2224 However, using the degree-based trigonometric functions is preferred,
2225 as that way avoids round-off error for special cases such
2226 as
<literal>sind(
30)
</literal>.
2231 <xref linkend=
"functions-math-hyp-table"/> shows the
2232 available hyperbolic functions.
2235 <table id=
"functions-math-hyp-table">
2236 <title>Hyperbolic Functions
</title>
2241 <entry role=
"func_table_entry"><para role=
"func_signature">
2255 <entry role=
"func_table_entry"><para role=
"func_signature">
2257 <primary>sinh
</primary>
2259 <function>sinh
</function> (
<type>double precision
</type> )
2260 <returnvalue>double precision
</returnvalue>
2266 <literal>sinh(
1)
</literal>
2267 <returnvalue>1.1752011936438014</returnvalue>
2272 <entry role=
"func_table_entry"><para role=
"func_signature">
2274 <primary>cosh
</primary>
2276 <function>cosh
</function> (
<type>double precision
</type> )
2277 <returnvalue>double precision
</returnvalue>
2283 <literal>cosh(
0)
</literal>
2284 <returnvalue>1</returnvalue>
2289 <entry role=
"func_table_entry"><para role=
"func_signature">
2291 <primary>tanh
</primary>
2293 <function>tanh
</function> (
<type>double precision
</type> )
2294 <returnvalue>double precision
</returnvalue>
2300 <literal>tanh(
1)
</literal>
2301 <returnvalue>0.7615941559557649</returnvalue>
2306 <entry role=
"func_table_entry"><para role=
"func_signature">
2308 <primary>asinh
</primary>
2310 <function>asinh
</function> (
<type>double precision
</type> )
2311 <returnvalue>double precision
</returnvalue>
2314 Inverse hyperbolic sine
2317 <literal>asinh(
1)
</literal>
2318 <returnvalue>0.881373587019543</returnvalue>
2323 <entry role=
"func_table_entry"><para role=
"func_signature">
2325 <primary>acosh
</primary>
2327 <function>acosh
</function> (
<type>double precision
</type> )
2328 <returnvalue>double precision
</returnvalue>
2331 Inverse hyperbolic cosine
2334 <literal>acosh(
1)
</literal>
2335 <returnvalue>0</returnvalue>
2340 <entry role=
"func_table_entry"><para role=
"func_signature">
2342 <primary>atanh
</primary>
2344 <function>atanh
</function> (
<type>double precision
</type> )
2345 <returnvalue>double precision
</returnvalue>
2348 Inverse hyperbolic tangent
2351 <literal>atanh(
0.5)
</literal>
2352 <returnvalue>0.5493061443340548</returnvalue>
2362 <sect1 id=
"functions-string">
2363 <title>String Functions and Operators
</title>
2366 This section describes functions and operators for examining and
2367 manipulating string values. Strings in this context include values
2368 of the types
<type>character
</type>,
<type>character varying
</type>,
2369 and
<type>text
</type>. Except where noted, these functions and operators
2370 are declared to accept and return type
<type>text
</type>. They will
2371 interchangeably accept
<type>character varying
</type> arguments.
2372 Values of type
<type>character
</type> will be converted
2373 to
<type>text
</type> before the function or operator is applied, resulting
2374 in stripping any trailing spaces in the
<type>character
</type> value.
2378 <acronym>SQL
</acronym> defines some string functions that use
2379 key words, rather than commas, to separate
2380 arguments. Details are in
2381 <xref linkend=
"functions-string-sql"/>.
2382 <productname>PostgreSQL
</productname> also provides versions of these functions
2383 that use the regular function invocation syntax
2384 (see
<xref linkend=
"functions-string-other"/>).
2389 The string concatenation operator (
<literal>||
</literal>) will accept
2390 non-string input, so long as at least one input is of string type, as shown
2391 in
<xref linkend=
"functions-string-sql"/>. For other cases, inserting an
2392 explicit coercion to
<type>text
</type> can be used to have non-string input
2397 <table id=
"functions-string-sql">
2398 <title><acronym>SQL
</acronym> String Functions and Operators
</title>
2402 <entry role=
"func_table_entry"><para role=
"func_signature">
2416 <entry role=
"func_table_entry"><para role=
"func_signature">
2418 <primary>character string
</primary>
2419 <secondary>concatenation
</secondary>
2421 <type>text
</type> <literal>||
</literal> <type>text
</type>
2422 <returnvalue>text
</returnvalue>
2425 Concatenates the two strings.
2428 <literal>'Post' || 'greSQL'
</literal>
2429 <returnvalue>PostgreSQL
</returnvalue>
2434 <entry role=
"func_table_entry"><para role=
"func_signature">
2435 <type>text
</type> <literal>||
</literal> <type>anynonarray
</type>
2436 <returnvalue>text
</returnvalue>
2438 <para role=
"func_signature">
2439 <type>anynonarray
</type> <literal>||
</literal> <type>text
</type>
2440 <returnvalue>text
</returnvalue>
2443 Converts the non-string input to text, then concatenates the two
2444 strings. (The non-string input cannot be of an array type, because
2445 that would create ambiguity with the array
<literal>||
</literal>
2446 operators. If you want to concatenate an array's text equivalent,
2447 cast it to
<type>text
</type> explicitly.)
2450 <literal>'Value: ' ||
42</literal>
2451 <returnvalue>Value:
42</returnvalue>
2456 <entry role=
"func_table_entry"><para role=
"func_signature">
2458 <primary>normalized
</primary>
2461 <primary>Unicode normalization
</primary>
2463 <type>text
</type> <literal>IS
</literal> <optional><literal>NOT
</literal></optional> <optional><parameter>form
</parameter></optional> <literal>NORMALIZED
</literal>
2464 <returnvalue>boolean
</returnvalue>
2467 Checks whether the string is in the specified Unicode normalization
2468 form. The optional
<parameter>form
</parameter> key word specifies the
2469 form:
<literal>NFC
</literal> (the default),
<literal>NFD
</literal>,
2470 <literal>NFKC
</literal>, or
<literal>NFKD
</literal>. This expression can
2471 only be used when the server encoding is
<literal>UTF8
</literal>. Note
2472 that checking for normalization using this expression is often faster
2473 than normalizing possibly already normalized strings.
2476 <literal>U
&'\
0061\
0308bc' IS NFD NORMALIZED
</literal>
2477 <returnvalue>t
</returnvalue>
2482 <entry role=
"func_table_entry"><para role=
"func_signature">
2484 <primary>bit_length
</primary>
2486 <function>bit_length
</function> (
<type>text
</type> )
2487 <returnvalue>integer
</returnvalue>
2490 Returns number of bits in the string (
8
2491 times the
<function>octet_length
</function>).
2494 <literal>bit_length('jose')
</literal>
2495 <returnvalue>32</returnvalue>
2500 <entry role=
"func_table_entry"><para role=
"func_signature">
2502 <primary>char_length
</primary>
2505 <primary>character string
</primary>
2506 <secondary>length
</secondary>
2509 <primary>length
</primary>
2510 <secondary sortas=
"character string">of a character string
</secondary>
2511 <see>character string, length
</see>
2513 <function>char_length
</function> (
<type>text
</type> )
2514 <returnvalue>integer
</returnvalue>
2516 <para role=
"func_signature">
2518 <primary>character_length
</primary>
2520 <function>character_length
</function> (
<type>text
</type> )
2521 <returnvalue>integer
</returnvalue>
2524 Returns number of characters in the string.
2527 <literal>char_length('jos
é')
</literal>
2528 <returnvalue>4</returnvalue>
2533 <entry role=
"func_table_entry"><para role=
"func_signature">
2535 <primary>lower
</primary>
2537 <function>lower
</function> (
<type>text
</type> )
2538 <returnvalue>text
</returnvalue>
2541 Converts the string to all lower case, according to the rules of the
2545 <literal>lower('TOM')
</literal>
2546 <returnvalue>tom
</returnvalue>
2551 <entry role=
"func_table_entry"><para role=
"func_signature">
2553 <primary>normalize
</primary>
2556 <primary>Unicode normalization
</primary>
2558 <function>normalize
</function> (
<type>text
</type>
2559 <optional>,
<parameter>form
</parameter> </optional> )
2560 <returnvalue>text
</returnvalue>
2563 Converts the string to the specified Unicode
2564 normalization form. The optional
<parameter>form
</parameter> key word
2565 specifies the form:
<literal>NFC
</literal> (the default),
2566 <literal>NFD
</literal>,
<literal>NFKC
</literal>, or
2567 <literal>NFKD
</literal>. This function can only be used when the
2568 server encoding is
<literal>UTF8
</literal>.
2571 <literal>normalize(U
&'\
0061\
0308bc', NFC)
</literal>
2572 <returnvalue>U
&'\
00E4bc'
</returnvalue>
2577 <entry role=
"func_table_entry"><para role=
"func_signature">
2579 <primary>octet_length
</primary>
2581 <function>octet_length
</function> (
<type>text
</type> )
2582 <returnvalue>integer
</returnvalue>
2585 Returns number of bytes in the string.
2588 <literal>octet_length('jos
é')
</literal>
2589 <returnvalue>5</returnvalue> (if server encoding is UTF8)
2594 <entry role=
"func_table_entry"><para role=
"func_signature">
2596 <primary>octet_length
</primary>
2598 <function>octet_length
</function> (
<type>character
</type> )
2599 <returnvalue>integer
</returnvalue>
2602 Returns number of bytes in the string. Since this version of the
2603 function accepts type
<type>character
</type> directly, it will not
2604 strip trailing spaces.
2607 <literal>octet_length('abc '::character(
4))
</literal>
2608 <returnvalue>4</returnvalue>
2613 <entry role=
"func_table_entry"><para role=
"func_signature">
2615 <primary>overlay
</primary>
2617 <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> )
2618 <returnvalue>text
</returnvalue>
2621 Replaces the substring of
<parameter>string
</parameter> that starts at
2622 the
<parameter>start
</parameter>'th character and extends
2623 for
<parameter>count
</parameter> characters
2624 with
<parameter>newsubstring
</parameter>.
2625 If
<parameter>count
</parameter> is omitted, it defaults to the length
2626 of
<parameter>newsubstring
</parameter>.
2629 <literal>overlay('Txxxxas' placing 'hom' from
2 for
4)
</literal>
2630 <returnvalue>Thomas
</returnvalue>
2635 <entry role=
"func_table_entry"><para role=
"func_signature">
2637 <primary>position
</primary>
2639 <function>position
</function> (
<parameter>substring
</parameter> <type>text
</type> <literal>IN
</literal> <parameter>string
</parameter> <type>text
</type> )
2640 <returnvalue>integer
</returnvalue>
2643 Returns first starting index of the specified
2644 <parameter>substring
</parameter> within
2645 <parameter>string
</parameter>, or zero if it's not present.
2648 <literal>position('om' in 'Thomas')
</literal>
2649 <returnvalue>3</returnvalue>
2654 <entry role=
"func_table_entry"><para role=
"func_signature">
2656 <primary>substring
</primary>
2658 <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> )
2659 <returnvalue>text
</returnvalue>
2662 Extracts the substring of
<parameter>string
</parameter> starting at
2663 the
<parameter>start
</parameter>'th character if that is specified,
2664 and stopping after
<parameter>count
</parameter> characters if that is
2665 specified. Provide at least one of
<parameter>start
</parameter>
2666 and
<parameter>count
</parameter>.
2669 <literal>substring('Thomas' from
2 for
3)
</literal>
2670 <returnvalue>hom
</returnvalue>
2673 <literal>substring('Thomas' from
3)
</literal>
2674 <returnvalue>omas
</returnvalue>
2677 <literal>substring('Thomas' for
2)
</literal>
2678 <returnvalue>Th
</returnvalue>
2683 <entry role=
"func_table_entry"><para role=
"func_signature">
2684 <function>substring
</function> (
<parameter>string
</parameter> <type>text
</type> <literal>FROM
</literal> <parameter>pattern
</parameter> <type>text
</type> )
2685 <returnvalue>text
</returnvalue>
2688 Extracts the first substring matching POSIX regular expression; see
2689 <xref linkend=
"functions-posix-regexp"/>.
2692 <literal>substring('Thomas' from '...$')
</literal>
2693 <returnvalue>mas
</returnvalue>
2698 <entry role=
"func_table_entry"><para role=
"func_signature">
2699 <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> )
2700 <returnvalue>text
</returnvalue>
2702 <para role=
"func_signature">
2703 <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> )
2704 <returnvalue>text
</returnvalue>
2707 Extracts the first substring matching
<acronym>SQL
</acronym> regular expression;
2708 see
<xref linkend=
"functions-similarto-regexp"/>. The first form has
2709 been specified since SQL:
2003; the second form was only in SQL:
1999
2710 and should be considered obsolete.
2713 <literal>substring('Thomas' similar '%#
"o_a#"_' escape '#')
</literal>
2714 <returnvalue>oma
</returnvalue>
2719 <entry role=
"func_table_entry"><para role=
"func_signature">
2721 <primary>trim
</primary>
2723 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional>
2724 <optional> <parameter>characters
</parameter> <type>text
</type> </optional> <literal>FROM
</literal>
2725 <parameter>string
</parameter> <type>text
</type> )
2726 <returnvalue>text
</returnvalue>
2729 Removes the longest string containing only characters in
2730 <parameter>characters
</parameter> (a space by default) from the
2731 start, end, or both ends (
<literal>BOTH
</literal> is the default)
2732 of
<parameter>string
</parameter>.
2735 <literal>trim(both 'xyz' from 'yxTomxx')
</literal>
2736 <returnvalue>Tom
</returnvalue>
2741 <entry role=
"func_table_entry"><para role=
"func_signature">
2742 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional> <optional> <literal>FROM
</literal> </optional>
2743 <parameter>string
</parameter> <type>text
</type> <optional>,
2744 <parameter>characters
</parameter> <type>text
</type> </optional> )
2745 <returnvalue>text
</returnvalue>
2748 This is a non-standard syntax for
<function>trim()
</function>.
2751 <literal>trim(both from 'yxTomxx', 'xyz')
</literal>
2752 <returnvalue>Tom
</returnvalue>
2757 <entry role=
"func_table_entry"><para role=
"func_signature">
2759 <primary>upper
</primary>
2761 <function>upper
</function> (
<type>text
</type> )
2762 <returnvalue>text
</returnvalue>
2765 Converts the string to all upper case, according to the rules of the
2769 <literal>upper('tom')
</literal>
2770 <returnvalue>TOM
</returnvalue>
2778 Additional string manipulation functions and operators are available
2779 and are listed in
<xref linkend=
"functions-string-other"/>. (Some of
2780 these are used internally to implement
2781 the
<acronym>SQL
</acronym>-standard string functions listed in
2782 <xref linkend=
"functions-string-sql"/>.)
2783 There are also pattern-matching operators, which are described in
2784 <xref linkend=
"functions-matching"/>, and operators for full-text
2785 search, which are described in
<xref linkend=
"textsearch"/>.
2788 <table id=
"functions-string-other">
2789 <title>Other String Functions and Operators
</title>
2793 <entry role=
"func_table_entry"><para role=
"func_signature">
2807 <entry role=
"func_table_entry"><para role=
"func_signature">
2809 <primary>character string
</primary>
2810 <secondary>prefix test
</secondary>
2812 <type>text
</type> <literal>^@
</literal> <type>text
</type>
2813 <returnvalue>boolean
</returnvalue>
2816 Returns true if the first string starts with the second string
2817 (equivalent to the
<function>starts_with()
</function> function).
2820 <literal>'alphabet' ^@ 'alph'
</literal>
2821 <returnvalue>t
</returnvalue>
2826 <entry role=
"func_table_entry"><para role=
"func_signature">
2828 <primary>ascii
</primary>
2830 <function>ascii
</function> (
<type>text
</type> )
2831 <returnvalue>integer
</returnvalue>
2834 Returns the numeric code of the first character of the argument.
2835 In
<acronym>UTF8
</acronym> encoding, returns the Unicode code point
2836 of the character. In other multibyte encodings, the argument must
2837 be an
<acronym>ASCII
</acronym> character.
2840 <literal>ascii('x')
</literal>
2841 <returnvalue>120</returnvalue>
2846 <entry role=
"func_table_entry"><para role=
"func_signature">
2848 <primary>btrim
</primary>
2850 <function>btrim
</function> (
<parameter>string
</parameter> <type>text
</type>
2851 <optional>,
<parameter>characters
</parameter> <type>text
</type> </optional> )
2852 <returnvalue>text
</returnvalue>
2855 Removes the longest string containing only characters
2856 in
<parameter>characters
</parameter> (a space by default)
2857 from the start and end of
<parameter>string
</parameter>.
2860 <literal>btrim('xyxtrimyyx', 'xyz')
</literal>
2861 <returnvalue>trim
</returnvalue>
2866 <entry role=
"func_table_entry"><para role=
"func_signature">
2868 <primary>chr
</primary>
2870 <function>chr
</function> (
<type>integer
</type> )
2871 <returnvalue>text
</returnvalue>
2874 Returns the character with the given code. In
<acronym>UTF8
</acronym>
2875 encoding the argument is treated as a Unicode code point. In other
2876 multibyte encodings the argument must designate
2877 an
<acronym>ASCII
</acronym> character.
<literal>chr(
0)
</literal> is
2878 disallowed because text data types cannot store that character.
2881 <literal>chr(
65)
</literal>
2882 <returnvalue>A
</returnvalue>
2887 <entry role=
"func_table_entry"><para role=
"func_signature">
2889 <primary>concat
</primary>
2891 <function>concat
</function> (
<parameter>val1
</parameter> <type>"any"</type>
2892 [,
<parameter>val2
</parameter> <type>"any"</type> [, ...] ] )
2893 <returnvalue>text
</returnvalue>
2896 Concatenates the text representations of all the arguments.
2897 NULL arguments are ignored.
2900 <literal>concat('abcde',
2, NULL,
22)
</literal>
2901 <returnvalue>abcde222
</returnvalue>
2906 <entry role=
"func_table_entry"><para role=
"func_signature">
2908 <primary>concat_ws
</primary>
2910 <function>concat_ws
</function> (
<parameter>sep
</parameter> <type>text
</type>,
2911 <parameter>val1
</parameter> <type>"any"</type>
2912 [,
<parameter>val2
</parameter> <type>"any"</type> [, ...] ] )
2913 <returnvalue>text
</returnvalue>
2916 Concatenates all but the first argument, with separators. The first
2917 argument is used as the separator string, and should not be NULL.
2918 Other NULL arguments are ignored.
2921 <literal>concat_ws(',', 'abcde',
2, NULL,
22)
</literal>
2922 <returnvalue>abcde,
2,
22</returnvalue>
2927 <entry role=
"func_table_entry"><para role=
"func_signature">
2929 <primary>format
</primary>
2931 <function>format
</function> (
<parameter>formatstr
</parameter> <type>text
</type>
2932 [,
<parameter>formatarg
</parameter> <type>"any"</type> [, ...] ] )
2933 <returnvalue>text
</returnvalue>
2936 Formats arguments according to a format string;
2937 see
<xref linkend=
"functions-string-format"/>.
2938 This function is similar to the C function
<function>sprintf
</function>.
2941 <literal>format('Hello %s, %
1$s', 'World')
</literal>
2942 <returnvalue>Hello World, World
</returnvalue>
2947 <entry role=
"func_table_entry"><para role=
"func_signature">
2949 <primary>initcap
</primary>
2951 <function>initcap
</function> (
<type>text
</type> )
2952 <returnvalue>text
</returnvalue>
2955 Converts the first letter of each word to upper case and the
2956 rest to lower case. Words are sequences of alphanumeric
2957 characters separated by non-alphanumeric characters.
2960 <literal>initcap('hi THOMAS')
</literal>
2961 <returnvalue>Hi Thomas
</returnvalue>
2966 <entry role=
"func_table_entry"><para role=
"func_signature">
2968 <primary>left
</primary>
2970 <function>left
</function> (
<parameter>string
</parameter> <type>text
</type>,
2971 <parameter>n
</parameter> <type>integer
</type> )
2972 <returnvalue>text
</returnvalue>
2975 Returns first
<parameter>n
</parameter> characters in the
2976 string, or when
<parameter>n
</parameter> is negative, returns
2977 all but last |
<parameter>n
</parameter>| characters.
2980 <literal>left('abcde',
2)
</literal>
2981 <returnvalue>ab
</returnvalue>
2986 <entry role=
"func_table_entry"><para role=
"func_signature">
2988 <primary>length
</primary>
2990 <function>length
</function> (
<type>text
</type> )
2991 <returnvalue>integer
</returnvalue>
2994 Returns the number of characters in the string.
2997 <literal>length('jose')
</literal>
2998 <returnvalue>4</returnvalue>
3003 <entry role=
"func_table_entry"><para role=
"func_signature">
3005 <primary>lpad
</primary>
3007 <function>lpad
</function> (
<parameter>string
</parameter> <type>text
</type>,
3008 <parameter>length
</parameter> <type>integer
</type>
3009 <optional>,
<parameter>fill
</parameter> <type>text
</type> </optional> )
3010 <returnvalue>text
</returnvalue>
3013 Extends the
<parameter>string
</parameter> to length
3014 <parameter>length
</parameter> by prepending the characters
3015 <parameter>fill
</parameter> (a space by default). If the
3016 <parameter>string
</parameter> is already longer than
3017 <parameter>length
</parameter> then it is truncated (on the right).
3020 <literal>lpad('hi',
5, 'xy')
</literal>
3021 <returnvalue>xyxhi
</returnvalue>
3026 <entry role=
"func_table_entry"><para role=
"func_signature">
3028 <primary>ltrim
</primary>
3030 <function>ltrim
</function> (
<parameter>string
</parameter> <type>text
</type>
3031 <optional>,
<parameter>characters
</parameter> <type>text
</type> </optional> )
3032 <returnvalue>text
</returnvalue>
3035 Removes the longest string containing only characters in
3036 <parameter>characters
</parameter> (a space by default) from the start of
3037 <parameter>string
</parameter>.
3040 <literal>ltrim('zzzytest', 'xyz')
</literal>
3041 <returnvalue>test
</returnvalue>
3046 <entry role=
"func_table_entry"><para role=
"func_signature">
3048 <primary>md5
</primary>
3050 <function>md5
</function> (
<type>text
</type> )
3051 <returnvalue>text
</returnvalue>
3054 Computes the MD5
<link linkend=
"functions-hash-note">hash
</link> of
3055 the argument, with the result written in hexadecimal.
3058 <literal>md5('abc')
</literal>
3059 <returnvalue>900150983cd24fb0
&zwsp;d6963f7d28e17f72
</returnvalue>
3064 <entry role=
"func_table_entry"><para role=
"func_signature">
3066 <primary>parse_ident
</primary>
3068 <function>parse_ident
</function> (
<parameter>qualified_identifier
</parameter> <type>text
</type>
3069 [,
<parameter>strict_mode
</parameter> <type>boolean
</type> <literal>DEFAULT
</literal> <literal>true
</literal> ] )
3070 <returnvalue>text[]
</returnvalue>
3073 Splits
<parameter>qualified_identifier
</parameter> into an array of
3074 identifiers, removing any quoting of individual identifiers. By
3075 default, extra characters after the last identifier are considered an
3076 error; but if the second parameter is
<literal>false
</literal>, then such
3077 extra characters are ignored. (This behavior is useful for parsing
3078 names for objects like functions.) Note that this function does not
3079 truncate over-length identifiers. If you want truncation you can cast
3080 the result to
<type>name[]
</type>.
3083 <literal>parse_ident('
"SomeSchema".someTable')
</literal>
3084 <returnvalue>{SomeSchema,sometable}
</returnvalue>
3089 <entry role=
"func_table_entry"><para role=
"func_signature">
3091 <primary>pg_client_encoding
</primary>
3093 <function>pg_client_encoding
</function> ( )
3094 <returnvalue>name
</returnvalue>
3097 Returns current client encoding name.
3100 <literal>pg_client_encoding()
</literal>
3101 <returnvalue>UTF8
</returnvalue>
3106 <entry role=
"func_table_entry"><para role=
"func_signature">
3108 <primary>quote_ident
</primary>
3110 <function>quote_ident
</function> (
<type>text
</type> )
3111 <returnvalue>text
</returnvalue>
3114 Returns the given string suitably quoted to be used as an identifier
3115 in an
<acronym>SQL
</acronym> statement string.
3116 Quotes are added only if necessary (i.e., if the string contains
3117 non-identifier characters or would be case-folded).
3118 Embedded quotes are properly doubled.
3119 See also
<xref linkend=
"plpgsql-quote-literal-example"/>.
3122 <literal>quote_ident('Foo bar')
</literal>
3123 <returnvalue>"Foo bar"</returnvalue>
3128 <entry role=
"func_table_entry"><para role=
"func_signature">
3130 <primary>quote_literal
</primary>
3132 <function>quote_literal
</function> (
<type>text
</type> )
3133 <returnvalue>text
</returnvalue>
3136 Returns the given string suitably quoted to be used as a string literal
3137 in an
<acronym>SQL
</acronym> statement string.
3138 Embedded single-quotes and backslashes are properly doubled.
3139 Note that
<function>quote_literal
</function> returns null on null
3140 input; if the argument might be null,
3141 <function>quote_nullable
</function> is often more suitable.
3142 See also
<xref linkend=
"plpgsql-quote-literal-example"/>.
3145 <literal>quote_literal(E'O\'Reilly')
</literal>
3146 <returnvalue>'O''Reilly'
</returnvalue>
3151 <entry role=
"func_table_entry"><para role=
"func_signature">
3152 <function>quote_literal
</function> (
<type>anyelement
</type> )
3153 <returnvalue>text
</returnvalue>
3156 Converts the given value to text and then quotes it as a literal.
3157 Embedded single-quotes and backslashes are properly doubled.
3160 <literal>quote_literal(
42.5)
</literal>
3161 <returnvalue>'
42.5'
</returnvalue>
3166 <entry role=
"func_table_entry"><para role=
"func_signature">
3168 <primary>quote_nullable
</primary>
3170 <function>quote_nullable
</function> (
<type>text
</type> )
3171 <returnvalue>text
</returnvalue>
3174 Returns the given string suitably quoted to be used as a string literal
3175 in an
<acronym>SQL
</acronym> statement string; or, if the argument
3176 is null, returns
<literal>NULL
</literal>.
3177 Embedded single-quotes and backslashes are properly doubled.
3178 See also
<xref linkend=
"plpgsql-quote-literal-example"/>.
3181 <literal>quote_nullable(NULL)
</literal>
3182 <returnvalue>NULL
</returnvalue>
3187 <entry role=
"func_table_entry"><para role=
"func_signature">
3188 <function>quote_nullable
</function> (
<type>anyelement
</type> )
3189 <returnvalue>text
</returnvalue>
3192 Converts the given value to text and then quotes it as a literal;
3193 or, if the argument is null, returns
<literal>NULL
</literal>.
3194 Embedded single-quotes and backslashes are properly doubled.
3197 <literal>quote_nullable(
42.5)
</literal>
3198 <returnvalue>'
42.5'
</returnvalue>
3203 <entry role=
"func_table_entry"><para role=
"func_signature">
3205 <primary>regexp_count
</primary>
3207 <function>regexp_count
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3208 [,
<parameter>start
</parameter> <type>integer
</type>
3209 [,
<parameter>flags
</parameter> <type>text
</type> ] ] )
3210 <returnvalue>integer
</returnvalue>
3213 Returns the number of times the POSIX regular
3214 expression
<parameter>pattern
</parameter> matches in
3215 the
<parameter>string
</parameter>; see
3216 <xref linkend=
"functions-posix-regexp"/>.
3219 <literal>regexp_count('
123456789012', '\d\d\d',
2)
</literal>
3220 <returnvalue>3</returnvalue>
3225 <entry role=
"func_table_entry"><para role=
"func_signature">
3227 <primary>regexp_instr
</primary>
3229 <function>regexp_instr
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3230 [,
<parameter>start
</parameter> <type>integer
</type>
3231 [,
<parameter>N
</parameter> <type>integer
</type>
3232 [,
<parameter>endoption
</parameter> <type>integer
</type>
3233 [,
<parameter>flags
</parameter> <type>text
</type>
3234 [,
<parameter>subexpr
</parameter> <type>integer
</type> ] ] ] ] ] )
3235 <returnvalue>integer
</returnvalue>
3238 Returns the position within
<parameter>string
</parameter> where
3239 the
<parameter>N
</parameter>'th match of the POSIX regular
3240 expression
<parameter>pattern
</parameter> occurs, or zero if there is
3241 no such match; see
<xref linkend=
"functions-posix-regexp"/>.
3244 <literal>regexp_instr('ABCDEF', 'c(.)(..)',
1,
1,
0, 'i')
</literal>
3245 <returnvalue>3</returnvalue>
3248 <literal>regexp_instr('ABCDEF', 'c(.)(..)',
1,
1,
0, 'i',
2)
</literal>
3249 <returnvalue>5</returnvalue>
3254 <entry role=
"func_table_entry"><para role=
"func_signature">
3256 <primary>regexp_like
</primary>
3258 <function>regexp_like
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3259 [,
<parameter>flags
</parameter> <type>text
</type> ] )
3260 <returnvalue>boolean
</returnvalue>
3263 Checks whether a match of the POSIX regular
3264 expression
<parameter>pattern
</parameter> occurs
3265 within
<parameter>string
</parameter>; see
3266 <xref linkend=
"functions-posix-regexp"/>.
3269 <literal>regexp_like('Hello World', 'world$', 'i')
</literal>
3270 <returnvalue>t
</returnvalue>
3275 <entry role=
"func_table_entry"><para role=
"func_signature">
3277 <primary>regexp_match
</primary>
3279 <function>regexp_match
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3280 <returnvalue>text[]
</returnvalue>
3283 Returns substrings within the first match of the POSIX regular
3284 expression
<parameter>pattern
</parameter> to
3285 the
<parameter>string
</parameter>; see
3286 <xref linkend=
"functions-posix-regexp"/>.
3289 <literal>regexp_match('foobarbequebaz', '(bar)(beque)')
</literal>
3290 <returnvalue>{bar,beque}
</returnvalue>
3295 <entry role=
"func_table_entry"><para role=
"func_signature">
3297 <primary>regexp_matches
</primary>
3299 <function>regexp_matches
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3300 <returnvalue>setof text[]
</returnvalue>
3303 Returns substrings within the first match of the POSIX regular
3304 expression
<parameter>pattern
</parameter> to
3305 the
<parameter>string
</parameter>, or substrings within all
3306 such matches if the
<literal>g
</literal> flag is used;
3307 see
<xref linkend=
"functions-posix-regexp"/>.
3310 <literal>regexp_matches('foobarbequebaz', 'ba.', 'g')
</literal>
3311 <returnvalue></returnvalue>
3320 <entry role=
"func_table_entry"><para role=
"func_signature">
3322 <primary>regexp_replace
</primary>
3324 <function>regexp_replace
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>,
<parameter>replacement
</parameter> <type>text
</type>
3325 [,
<parameter>start
</parameter> <type>integer
</type> ]
3326 [,
<parameter>flags
</parameter> <type>text
</type> ] )
3327 <returnvalue>text
</returnvalue>
3330 Replaces the substring that is the first match to the POSIX
3331 regular expression
<parameter>pattern
</parameter>, or all such
3332 matches if the
<literal>g
</literal> flag is used; see
3333 <xref linkend=
"functions-posix-regexp"/>.
3336 <literal>regexp_replace('Thomas', '.[mN]a.', 'M')
</literal>
3337 <returnvalue>ThM
</returnvalue>
3342 <entry role=
"func_table_entry"><para role=
"func_signature">
3343 <function>regexp_replace
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>,
<parameter>replacement
</parameter> <type>text
</type>,
3344 <parameter>start
</parameter> <type>integer
</type>,
3345 <parameter>N
</parameter> <type>integer
</type>
3346 [,
<parameter>flags
</parameter> <type>text
</type> ] )
3347 <returnvalue>text
</returnvalue>
3350 Replaces the substring that is the
<parameter>N
</parameter>'th
3351 match to the POSIX regular expression
<parameter>pattern
</parameter>,
3352 or all such matches if
<parameter>N
</parameter> is zero; see
3353 <xref linkend=
"functions-posix-regexp"/>.
3356 <literal>regexp_replace('Thomas', '.', 'X',
3,
2)
</literal>
3357 <returnvalue>ThoXas
</returnvalue>
3362 <entry role=
"func_table_entry"><para role=
"func_signature">
3364 <primary>regexp_split_to_array
</primary>
3366 <function>regexp_split_to_array
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3367 <returnvalue>text[]
</returnvalue>
3370 Splits
<parameter>string
</parameter> using a POSIX regular
3371 expression as the delimiter, producing an array of results; see
3372 <xref linkend=
"functions-posix-regexp"/>.
3375 <literal>regexp_split_to_array('hello world', '\s+')
</literal>
3376 <returnvalue>{hello,world}
</returnvalue>
3381 <entry role=
"func_table_entry"><para role=
"func_signature">
3383 <primary>regexp_split_to_table
</primary>
3385 <function>regexp_split_to_table
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ] )
3386 <returnvalue>setof text
</returnvalue>
3389 Splits
<parameter>string
</parameter> using a POSIX regular
3390 expression as the delimiter, producing a set of results; see
3391 <xref linkend=
"functions-posix-regexp"/>.
3394 <literal>regexp_split_to_table('hello world', '\s+')
</literal>
3395 <returnvalue></returnvalue>
3404 <entry role=
"func_table_entry"><para role=
"func_signature">
3406 <primary>regexp_substr
</primary>
3408 <function>regexp_substr
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>
3409 [,
<parameter>start
</parameter> <type>integer
</type>
3410 [,
<parameter>N
</parameter> <type>integer
</type>
3411 [,
<parameter>flags
</parameter> <type>text
</type>
3412 [,
<parameter>subexpr
</parameter> <type>integer
</type> ] ] ] ] )
3413 <returnvalue>text
</returnvalue>
3416 Returns the substring within
<parameter>string
</parameter> that
3417 matches the
<parameter>N
</parameter>'th occurrence of the POSIX
3418 regular expression
<parameter>pattern
</parameter>,
3419 or
<literal>NULL
</literal> if there is no such match; see
3420 <xref linkend=
"functions-posix-regexp"/>.
3423 <literal>regexp_substr('ABCDEF', 'c(.)(..)',
1,
1, 'i')
</literal>
3424 <returnvalue>CDEF
</returnvalue>
3427 <literal>regexp_substr('ABCDEF', 'c(.)(..)',
1,
1, 'i',
2)
</literal>
3428 <returnvalue>EF
</returnvalue>
3433 <entry role=
"func_table_entry"><para role=
"func_signature">
3435 <primary>repeat
</primary>
3437 <function>repeat
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>number
</parameter> <type>integer
</type> )
3438 <returnvalue>text
</returnvalue>
3441 Repeats
<parameter>string
</parameter> the specified
3442 <parameter>number
</parameter> of times.
3445 <literal>repeat('Pg',
4)
</literal>
3446 <returnvalue>PgPgPgPg
</returnvalue>
3451 <entry role=
"func_table_entry"><para role=
"func_signature">
3453 <primary>replace
</primary>
3455 <function>replace
</function> (
<parameter>string
</parameter> <type>text
</type>,
3456 <parameter>from
</parameter> <type>text
</type>,
3457 <parameter>to
</parameter> <type>text
</type> )
3458 <returnvalue>text
</returnvalue>
3461 Replaces all occurrences in
<parameter>string
</parameter> of
3462 substring
<parameter>from
</parameter> with
3463 substring
<parameter>to
</parameter>.
3466 <literal>replace('abcdefabcdef', 'cd', 'XX')
</literal>
3467 <returnvalue>abXXefabXXef
</returnvalue>
3472 <entry role=
"func_table_entry"><para role=
"func_signature">
3474 <primary>reverse
</primary>
3476 <function>reverse
</function> (
<type>text
</type> )
3477 <returnvalue>text
</returnvalue>
3480 Reverses the order of the characters in the string.
3483 <literal>reverse('abcde')
</literal>
3484 <returnvalue>edcba
</returnvalue>
3489 <entry role=
"func_table_entry"><para role=
"func_signature">
3491 <primary>right
</primary>
3493 <function>right
</function> (
<parameter>string
</parameter> <type>text
</type>,
3494 <parameter>n
</parameter> <type>integer
</type> )
3495 <returnvalue>text
</returnvalue>
3498 Returns last
<parameter>n
</parameter> characters in the string,
3499 or when
<parameter>n
</parameter> is negative, returns all but
3500 first |
<parameter>n
</parameter>| characters.
3503 <literal>right('abcde',
2)
</literal>
3504 <returnvalue>de
</returnvalue>
3509 <entry role=
"func_table_entry"><para role=
"func_signature">
3511 <primary>rpad
</primary>
3513 <function>rpad
</function> (
<parameter>string
</parameter> <type>text
</type>,
3514 <parameter>length
</parameter> <type>integer
</type>
3515 <optional>,
<parameter>fill
</parameter> <type>text
</type> </optional> )
3516 <returnvalue>text
</returnvalue>
3519 Extends the
<parameter>string
</parameter> to length
3520 <parameter>length
</parameter> by appending the characters
3521 <parameter>fill
</parameter> (a space by default). If the
3522 <parameter>string
</parameter> is already longer than
3523 <parameter>length
</parameter> then it is truncated.
3526 <literal>rpad('hi',
5, 'xy')
</literal>
3527 <returnvalue>hixyx
</returnvalue>
3532 <entry role=
"func_table_entry"><para role=
"func_signature">
3534 <primary>rtrim
</primary>
3536 <function>rtrim
</function> (
<parameter>string
</parameter> <type>text
</type>
3537 <optional>,
<parameter>characters
</parameter> <type>text
</type> </optional> )
3538 <returnvalue>text
</returnvalue>
3541 Removes the longest string containing only characters in
3542 <parameter>characters
</parameter> (a space by default) from the end of
3543 <parameter>string
</parameter>.
3546 <literal>rtrim('testxxzx', 'xyz')
</literal>
3547 <returnvalue>test
</returnvalue>
3552 <entry role=
"func_table_entry"><para role=
"func_signature">
3554 <primary>split_part
</primary>
3556 <function>split_part
</function> (
<parameter>string
</parameter> <type>text
</type>,
3557 <parameter>delimiter
</parameter> <type>text
</type>,
3558 <parameter>n
</parameter> <type>integer
</type> )
3559 <returnvalue>text
</returnvalue>
3562 Splits
<parameter>string
</parameter> at occurrences
3563 of
<parameter>delimiter
</parameter> and returns
3564 the
<parameter>n
</parameter>'th field (counting from one),
3565 or when
<parameter>n
</parameter> is negative, returns
3566 the |
<parameter>n
</parameter>|'th-from-last field.
3569 <literal>split_part('abc~@~def~@~ghi', '~@~',
2)
</literal>
3570 <returnvalue>def
</returnvalue>
3573 <literal>split_part('abc,def,ghi,jkl', ',', -
2)
</literal>
3574 <returnvalue>ghi
</returnvalue>
3579 <entry role=
"func_table_entry"><para role=
"func_signature">
3581 <primary>starts_with
</primary>
3583 <function>starts_with
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>prefix
</parameter> <type>text
</type> )
3584 <returnvalue>boolean
</returnvalue>
3587 Returns true if
<parameter>string
</parameter> starts
3588 with
<parameter>prefix
</parameter>.
3591 <literal>starts_with('alphabet', 'alph')
</literal>
3592 <returnvalue>t
</returnvalue>
3597 <entry role=
"func_table_entry"><para role=
"func_signature">
3598 <indexterm id=
"function-string-to-array">
3599 <primary>string_to_array
</primary>
3601 <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> )
3602 <returnvalue>text[]
</returnvalue>
3605 Splits the
<parameter>string
</parameter> at occurrences
3606 of
<parameter>delimiter
</parameter> and forms the resulting fields
3607 into a
<type>text
</type> array.
3608 If
<parameter>delimiter
</parameter> is
<literal>NULL
</literal>,
3609 each character in the
<parameter>string
</parameter> will become a
3610 separate element in the array.
3611 If
<parameter>delimiter
</parameter> is an empty string, then
3612 the
<parameter>string
</parameter> is treated as a single field.
3613 If
<parameter>null_string
</parameter> is supplied and is
3614 not
<literal>NULL
</literal>, fields matching that string are
3615 replaced by
<literal>NULL
</literal>.
3616 See also
<link linkend=
"function-array-to-string"><function>array_to_string
</function></link>.
3619 <literal>string_to_array('xx~~yy~~zz', '~~', 'yy')
</literal>
3620 <returnvalue>{xx,NULL,zz}
</returnvalue>
3625 <entry role=
"func_table_entry"><para role=
"func_signature">
3627 <primary>string_to_table
</primary>
3629 <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> )
3630 <returnvalue>setof text
</returnvalue>
3633 Splits the
<parameter>string
</parameter> at occurrences
3634 of
<parameter>delimiter
</parameter> and returns the resulting fields
3635 as a set of
<type>text
</type> rows.
3636 If
<parameter>delimiter
</parameter> is
<literal>NULL
</literal>,
3637 each character in the
<parameter>string
</parameter> will become a
3638 separate row of the result.
3639 If
<parameter>delimiter
</parameter> is an empty string, then
3640 the
<parameter>string
</parameter> is treated as a single field.
3641 If
<parameter>null_string
</parameter> is supplied and is
3642 not
<literal>NULL
</literal>, fields matching that string are
3643 replaced by
<literal>NULL
</literal>.
3646 <literal>string_to_table('xx~^~yy~^~zz', '~^~', 'yy')
</literal>
3647 <returnvalue></returnvalue>
3657 <entry role=
"func_table_entry"><para role=
"func_signature">
3659 <primary>strpos
</primary>
3661 <function>strpos
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>substring
</parameter> <type>text
</type> )
3662 <returnvalue>integer
</returnvalue>
3665 Returns first starting index of the specified
<parameter>substring
</parameter>
3666 within
<parameter>string
</parameter>, or zero if it's not present.
3667 (Same as
<literal>position(
<parameter>substring
</parameter> in
3668 <parameter>string
</parameter>)
</literal>, but note the reversed
3672 <literal>strpos('high', 'ig')
</literal>
3673 <returnvalue>2</returnvalue>
3678 <entry role=
"func_table_entry"><para role=
"func_signature">
3680 <primary>substr
</primary>
3682 <function>substr
</function> (
<parameter>string
</parameter> <type>text
</type>,
<parameter>start
</parameter> <type>integer
</type> <optional>,
<parameter>count
</parameter> <type>integer
</type> </optional> )
3683 <returnvalue>text
</returnvalue>
3686 Extracts the substring of
<parameter>string
</parameter> starting at
3687 the
<parameter>start
</parameter>'th character,
3688 and extending for
<parameter>count
</parameter> characters if that is
3690 as
<literal>substring(
<parameter>string
</parameter>
3691 from
<parameter>start
</parameter>
3692 for
<parameter>count
</parameter>)
</literal>.)
3695 <literal>substr('alphabet',
3)
</literal>
3696 <returnvalue>phabet
</returnvalue>
3699 <literal>substr('alphabet',
3,
2)
</literal>
3700 <returnvalue>ph
</returnvalue>
3705 <entry role=
"func_table_entry"><para role=
"func_signature">
3707 <primary>to_ascii
</primary>
3709 <function>to_ascii
</function> (
<parameter>string
</parameter> <type>text
</type> )
3710 <returnvalue>text
</returnvalue>
3712 <para role=
"func_signature">
3713 <function>to_ascii
</function> (
<parameter>string
</parameter> <type>text
</type>,
3714 <parameter>encoding
</parameter> <type>name
</type> )
3715 <returnvalue>text
</returnvalue>
3717 <para role=
"func_signature">
3718 <function>to_ascii
</function> (
<parameter>string
</parameter> <type>text
</type>,
3719 <parameter>encoding
</parameter> <type>integer
</type> )
3720 <returnvalue>text
</returnvalue>
3723 Converts
<parameter>string
</parameter> to
<acronym>ASCII
</acronym>
3724 from another encoding, which may be identified by name or number.
3725 If
<parameter>encoding
</parameter> is omitted the database encoding
3726 is assumed (which in practice is the only useful case).
3727 The conversion consists primarily of dropping accents.
3728 Conversion is only supported
3729 from
<literal>LATIN1
</literal>,
<literal>LATIN2
</literal>,
3730 <literal>LATIN9
</literal>, and
<literal>WIN1250
</literal> encodings.
3731 (See the
<xref linkend=
"unaccent"/> module for another, more flexible
3735 <literal>to_ascii('Kar
él')
</literal>
3736 <returnvalue>Karel
</returnvalue>
3741 <entry role=
"func_table_entry"><para role=
"func_signature">
3743 <primary>to_hex
</primary>
3745 <function>to_hex
</function> (
<type>integer
</type> )
3746 <returnvalue>text
</returnvalue>
3748 <para role=
"func_signature">
3749 <function>to_hex
</function> (
<type>bigint
</type> )
3750 <returnvalue>text
</returnvalue>
3753 Converts the number to its equivalent hexadecimal representation.
3756 <literal>to_hex(
2147483647)
</literal>
3757 <returnvalue>7fffffff
</returnvalue>
3762 <entry role=
"func_table_entry"><para role=
"func_signature">
3764 <primary>translate
</primary>
3766 <function>translate
</function> (
<parameter>string
</parameter> <type>text
</type>,
3767 <parameter>from
</parameter> <type>text
</type>,
3768 <parameter>to
</parameter> <type>text
</type> )
3769 <returnvalue>text
</returnvalue>
3772 Replaces each character in
<parameter>string
</parameter> that
3773 matches a character in the
<parameter>from
</parameter> set with the
3774 corresponding character in the
<parameter>to
</parameter>
3775 set. If
<parameter>from
</parameter> is longer than
3776 <parameter>to
</parameter>, occurrences of the extra characters in
3777 <parameter>from
</parameter> are deleted.
3780 <literal>translate('
12345', '
143', 'ax')
</literal>
3781 <returnvalue>a2x5
</returnvalue>
3786 <entry role=
"func_table_entry"><para role=
"func_signature">
3788 <primary>unistr
</primary>
3790 <function>unistr
</function> (
<type>text
</type> )
3791 <returnvalue>text
</returnvalue>
3794 Evaluate escaped Unicode characters in the argument. Unicode characters
3796 <literal>\
<replaceable>XXXX
</replaceable></literal> (
4 hexadecimal
3797 digits),
<literal>\+
<replaceable>XXXXXX
</replaceable></literal> (
6
3798 hexadecimal digits),
3799 <literal>\u
<replaceable>XXXX
</replaceable></literal> (
4 hexadecimal
3800 digits), or
<literal>\U
<replaceable>XXXXXXXX
</replaceable></literal>
3801 (
8 hexadecimal digits). To specify a backslash, write two
3802 backslashes. All other characters are taken literally.
3806 If the server encoding is not UTF-
8, the Unicode code point identified
3807 by one of these escape sequences is converted to the actual server
3808 encoding; an error is reported if that's not possible.
3812 This function provides a (non-standard) alternative to string
3813 constants with Unicode escapes (see
<xref
3814 linkend=
"sql-syntax-strings-uescape"/>).
3818 <literal>unistr('d\
0061t\+
000061')
</literal>
3819 <returnvalue>data
</returnvalue>
3822 <literal>unistr('d\u0061t\U00000061')
</literal>
3823 <returnvalue>data
</returnvalue>
3832 The
<function>concat
</function>,
<function>concat_ws
</function> and
3833 <function>format
</function> functions are variadic, so it is possible to
3834 pass the values to be concatenated or formatted as an array marked with
3835 the
<literal>VARIADIC
</literal> keyword (see
<xref
3836 linkend=
"xfunc-sql-variadic-functions"/>). The array's elements are
3837 treated as if they were separate ordinary arguments to the function.
3838 If the variadic array argument is NULL,
<function>concat
</function>
3839 and
<function>concat_ws
</function> return NULL, but
3840 <function>format
</function> treats a NULL as a zero-element array.
3844 See also the aggregate function
<function>string_agg
</function> in
3845 <xref linkend=
"functions-aggregate"/>, and the functions for
3846 converting between strings and the
<type>bytea
</type> type in
3847 <xref linkend=
"functions-binarystring-conversions"/>.
3850 <sect2 id=
"functions-string-format">
3851 <title><function>format
</function></title>
3854 <primary>format
</primary>
3858 The function
<function>format
</function> produces output formatted according to
3859 a format string, in a style similar to the C function
3860 <function>sprintf
</function>.
3865 <function>format
</function>(
<parameter>formatstr
</parameter> <type>text
</type> [,
<parameter>formatarg
</parameter> <type>"any"</type> [, ...] ])
3867 <parameter>formatstr
</parameter> is a format string that specifies how the
3868 result should be formatted. Text in the format string is copied
3869 directly to the result, except where
<firstterm>format specifiers
</firstterm> are
3870 used. Format specifiers act as placeholders in the string, defining how
3871 subsequent function arguments should be formatted and inserted into the
3872 result. Each
<parameter>formatarg
</parameter> argument is converted to text
3873 according to the usual output rules for its data type, and then formatted
3874 and inserted into the result string according to the format specifier(s).
3878 Format specifiers are introduced by a
<literal>%
</literal> character and have
3881 %[
<parameter>position
</parameter>][
<parameter>flags
</parameter>][
<parameter>width
</parameter>]
<parameter>type
</parameter>
3883 where the component fields are:
3887 <term><parameter>position
</parameter> (optional)
</term>
3890 A string of the form
<literal><parameter>n
</parameter>$
</literal> where
3891 <parameter>n
</parameter> is the index of the argument to print.
3892 Index
1 means the first argument after
3893 <parameter>formatstr
</parameter>. If the
<parameter>position
</parameter> is
3894 omitted, the default is to use the next argument in sequence.
3900 <term><parameter>flags
</parameter> (optional)
</term>
3903 Additional options controlling how the format specifier's output is
3904 formatted. Currently the only supported flag is a minus sign
3905 (
<literal>-
</literal>) which will cause the format specifier's output to be
3906 left-justified. This has no effect unless the
<parameter>width
</parameter>
3907 field is also specified.
3913 <term><parameter>width
</parameter> (optional)
</term>
3916 Specifies the
<emphasis>minimum
</emphasis> number of characters to use to
3917 display the format specifier's output. The output is padded on the
3918 left or right (depending on the
<literal>-
</literal> flag) with spaces as
3919 needed to fill the width. A too-small width does not cause
3920 truncation of the output, but is simply ignored. The width may be
3921 specified using any of the following: a positive integer; an
3922 asterisk (
<literal>*
</literal>) to use the next function argument as the
3923 width; or a string of the form
<literal>*
<parameter>n
</parameter>$
</literal> to
3924 use the
<parameter>n
</parameter>th function argument as the width.
3928 If the width comes from a function argument, that argument is
3929 consumed before the argument that is used for the format specifier's
3930 value. If the width argument is negative, the result is left
3931 aligned (as if the
<literal>-
</literal> flag had been specified) within a
3932 field of length
<function>abs
</function>(
<parameter>width
</parameter>).
3938 <term><parameter>type
</parameter> (required)
</term>
3941 The type of format conversion to use to produce the format
3942 specifier's output. The following types are supported:
3946 <literal>s
</literal> formats the argument value as a simple
3947 string. A null value is treated as an empty string.
3952 <literal>I
</literal> treats the argument value as an SQL
3953 identifier, double-quoting it if necessary.
3954 It is an error for the value to be null (equivalent to
3955 <function>quote_ident
</function>).
3960 <literal>L
</literal> quotes the argument value as an SQL literal.
3961 A null value is displayed as the string
<literal>NULL
</literal>, without
3962 quotes (equivalent to
<function>quote_nullable
</function>).
3973 In addition to the format specifiers described above, the special sequence
3974 <literal>%%
</literal> may be used to output a literal
<literal>%
</literal> character.
3978 Here are some examples of the basic format conversions:
3981 SELECT format('Hello %s', 'World');
3982 <lineannotation>Result:
</lineannotation><computeroutput>Hello World
</computeroutput>
3984 SELECT format('Testing %s, %s, %s, %%', 'one', 'two', 'three');
3985 <lineannotation>Result:
</lineannotation><computeroutput>Testing one, two, three, %
</computeroutput>
3987 SELECT format('INSERT INTO %I VALUES(%L)', 'Foo bar', E'O\'Reilly');
3988 <lineannotation>Result:
</lineannotation><computeroutput>INSERT INTO
"Foo bar" VALUES('O''Reilly')
</computeroutput>
3990 SELECT format('INSERT INTO %I VALUES(%L)', 'locations', 'C:\Program Files');
3991 <lineannotation>Result:
</lineannotation><computeroutput>INSERT INTO locations VALUES('C:\Program Files')
</computeroutput>
3996 Here are examples using
<parameter>width
</parameter> fields
3997 and the
<literal>-
</literal> flag:
4000 SELECT format('|%
10s|', 'foo');
4001 <lineannotation>Result:
</lineannotation><computeroutput>| foo|
</computeroutput>
4003 SELECT format('|%-
10s|', 'foo');
4004 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4006 SELECT format('|%*s|',
10, 'foo');
4007 <lineannotation>Result:
</lineannotation><computeroutput>| foo|
</computeroutput>
4009 SELECT format('|%*s|', -
10, 'foo');
4010 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4012 SELECT format('|%-*s|',
10, 'foo');
4013 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4015 SELECT format('|%-*s|', -
10, 'foo');
4016 <lineannotation>Result:
</lineannotation><computeroutput>|foo |
</computeroutput>
4021 These examples show use of
<parameter>position
</parameter> fields:
4024 SELECT format('Testing %
3$s, %
2$s, %
1$s', 'one', 'two', 'three');
4025 <lineannotation>Result:
</lineannotation><computeroutput>Testing three, two, one
</computeroutput>
4027 SELECT format('|%*
2$s|', 'foo',
10, 'bar');
4028 <lineannotation>Result:
</lineannotation><computeroutput>| bar|
</computeroutput>
4030 SELECT format('|%
1$*
2$s|', 'foo',
10, 'bar');
4031 <lineannotation>Result:
</lineannotation><computeroutput>| foo|
</computeroutput>
4036 Unlike the standard C function
<function>sprintf
</function>,
4037 <productname>PostgreSQL
</productname>'s
<function>format
</function> function allows format
4038 specifiers with and without
<parameter>position
</parameter> fields to be mixed
4039 in the same format string. A format specifier without a
4040 <parameter>position
</parameter> field always uses the next argument after the
4041 last argument consumed.
4042 In addition, the
<function>format
</function> function does not require all
4043 function arguments to be used in the format string.
4047 SELECT format('Testing %
3$s, %
2$s, %s', 'one', 'two', 'three');
4048 <lineannotation>Result:
</lineannotation><computeroutput>Testing three, two, three
</computeroutput>
4053 The
<literal>%I
</literal> and
<literal>%L
</literal> format specifiers are particularly
4054 useful for safely constructing dynamic SQL statements. See
4055 <xref linkend=
"plpgsql-quote-literal-example"/>.
4062 <sect1 id=
"functions-binarystring">
4063 <title>Binary String Functions and Operators
</title>
4065 <indexterm zone=
"functions-binarystring">
4066 <primary>binary data
</primary>
4067 <secondary>functions
</secondary>
4071 This section describes functions and operators for examining and
4072 manipulating binary strings, that is values of type
<type>bytea
</type>.
4073 Many of these are equivalent, in purpose and syntax, to the
4074 text-string functions described in the previous section.
4078 <acronym>SQL
</acronym> defines some string functions that use
4079 key words, rather than commas, to separate
4080 arguments. Details are in
4081 <xref linkend=
"functions-binarystring-sql"/>.
4082 <productname>PostgreSQL
</productname> also provides versions of these functions
4083 that use the regular function invocation syntax
4084 (see
<xref linkend=
"functions-binarystring-other"/>).
4087 <table id=
"functions-binarystring-sql">
4088 <title><acronym>SQL
</acronym> Binary String Functions and Operators
</title>
4092 <entry role=
"func_table_entry"><para role=
"func_signature">
4106 <entry role=
"func_table_entry"><para role=
"func_signature">
4108 <primary>binary string
</primary>
4109 <secondary>concatenation
</secondary>
4111 <type>bytea
</type> <literal>||
</literal> <type>bytea
</type>
4112 <returnvalue>bytea
</returnvalue>
4115 Concatenates the two binary strings.
4118 <literal>'\x123456'::bytea || '\x789a00bcde'::bytea
</literal>
4119 <returnvalue>\x123456789a00bcde
</returnvalue>
4124 <entry role=
"func_table_entry"><para role=
"func_signature">
4126 <primary>bit_length
</primary>
4128 <function>bit_length
</function> (
<type>bytea
</type> )
4129 <returnvalue>integer
</returnvalue>
4132 Returns number of bits in the binary string (
8
4133 times the
<function>octet_length
</function>).
4136 <literal>bit_length('\x123456'::bytea)
</literal>
4137 <returnvalue>24</returnvalue>
4142 <entry role=
"func_table_entry"><para role=
"func_signature">
4144 <primary>octet_length
</primary>
4146 <function>octet_length
</function> (
<type>bytea
</type> )
4147 <returnvalue>integer
</returnvalue>
4150 Returns number of bytes in the binary string.
4153 <literal>octet_length('\x123456'::bytea)
</literal>
4154 <returnvalue>3</returnvalue>
4159 <entry role=
"func_table_entry"><para role=
"func_signature">
4161 <primary>overlay
</primary>
4163 <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> )
4164 <returnvalue>bytea
</returnvalue>
4167 Replaces the substring of
<parameter>bytes
</parameter> that starts at
4168 the
<parameter>start
</parameter>'th byte and extends
4169 for
<parameter>count
</parameter> bytes
4170 with
<parameter>newsubstring
</parameter>.
4171 If
<parameter>count
</parameter> is omitted, it defaults to the length
4172 of
<parameter>newsubstring
</parameter>.
4175 <literal>overlay('\x1234567890'::bytea placing '\
002\
003'::bytea from
2 for
3)
</literal>
4176 <returnvalue>\x12020390
</returnvalue>
4181 <entry role=
"func_table_entry"><para role=
"func_signature">
4183 <primary>position
</primary>
4185 <function>position
</function> (
<parameter>substring
</parameter> <type>bytea
</type> <literal>IN
</literal> <parameter>bytes
</parameter> <type>bytea
</type> )
4186 <returnvalue>integer
</returnvalue>
4189 Returns first starting index of the specified
4190 <parameter>substring
</parameter> within
4191 <parameter>bytes
</parameter>, or zero if it's not present.
4194 <literal>position('\x5678'::bytea in '\x1234567890'::bytea)
</literal>
4195 <returnvalue>3</returnvalue>
4200 <entry role=
"func_table_entry"><para role=
"func_signature">
4202 <primary>substring
</primary>
4204 <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> )
4205 <returnvalue>bytea
</returnvalue>
4208 Extracts the substring of
<parameter>bytes
</parameter> starting at
4209 the
<parameter>start
</parameter>'th byte if that is specified,
4210 and stopping after
<parameter>count
</parameter> bytes if that is
4211 specified. Provide at least one of
<parameter>start
</parameter>
4212 and
<parameter>count
</parameter>.
4215 <literal>substring('\x1234567890'::bytea from
3 for
2)
</literal>
4216 <returnvalue>\x5678
</returnvalue>
4221 <entry role=
"func_table_entry"><para role=
"func_signature">
4223 <primary>trim
</primary>
4225 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional>
4226 <parameter>bytesremoved
</parameter> <type>bytea
</type> <literal>FROM
</literal>
4227 <parameter>bytes
</parameter> <type>bytea
</type> )
4228 <returnvalue>bytea
</returnvalue>
4231 Removes the longest string containing only bytes appearing in
4232 <parameter>bytesremoved
</parameter> from the start,
4233 end, or both ends (
<literal>BOTH
</literal> is the default)
4234 of
<parameter>bytes
</parameter>.
4237 <literal>trim('\x9012'::bytea from '\x1234567890'::bytea)
</literal>
4238 <returnvalue>\x345678
</returnvalue>
4243 <entry role=
"func_table_entry"><para role=
"func_signature">
4244 <function>trim
</function> (
<optional> <literal>LEADING
</literal> |
<literal>TRAILING
</literal> |
<literal>BOTH
</literal> </optional> <optional> <literal>FROM
</literal> </optional>
4245 <parameter>bytes
</parameter> <type>bytea
</type>,
4246 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4247 <returnvalue>bytea
</returnvalue>
4250 This is a non-standard syntax for
<function>trim()
</function>.
4253 <literal>trim(both from '\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4254 <returnvalue>\x345678
</returnvalue>
4262 Additional binary string manipulation functions are available and
4263 are listed in
<xref linkend=
"functions-binarystring-other"/>. Some
4264 of them are used internally to implement the
4265 <acronym>SQL
</acronym>-standard string functions listed in
<xref
4266 linkend=
"functions-binarystring-sql"/>.
4269 <table id=
"functions-binarystring-other">
4270 <title>Other Binary String Functions
</title>
4274 <entry role=
"func_table_entry"><para role=
"func_signature">
4288 <entry role=
"func_table_entry"><para role=
"func_signature">
4290 <primary>bit_count
</primary>
4293 <primary>popcount
</primary>
4294 <see>bit_count
</see>
4296 <function>bit_count
</function> (
<parameter>bytes
</parameter> <type>bytea
</type> )
4297 <returnvalue>bigint
</returnvalue>
4300 Returns the number of bits set in the binary string (also known as
4301 <quote>popcount
</quote>).
4304 <literal>bit_count('\x1234567890'::bytea)
</literal>
4305 <returnvalue>15</returnvalue>
4310 <entry role=
"func_table_entry"><para role=
"func_signature">
4312 <primary>btrim
</primary>
4314 <function>btrim
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4315 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4316 <returnvalue>bytea
</returnvalue>
4319 Removes the longest string containing only bytes appearing in
4320 <parameter>bytesremoved
</parameter> from the start and end of
4321 <parameter>bytes
</parameter>.
4324 <literal>btrim('\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4325 <returnvalue>\x345678
</returnvalue>
4330 <entry role=
"func_table_entry"><para role=
"func_signature">
4332 <primary>get_bit
</primary>
4334 <function>get_bit
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4335 <parameter>n
</parameter> <type>bigint
</type> )
4336 <returnvalue>integer
</returnvalue>
4339 Extracts
<link linkend=
"functions-zerobased-note">n'th
</link> bit
4343 <literal>get_bit('\x1234567890'::bytea,
30)
</literal>
4344 <returnvalue>1</returnvalue>
4349 <entry role=
"func_table_entry"><para role=
"func_signature">
4351 <primary>get_byte
</primary>
4353 <function>get_byte
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4354 <parameter>n
</parameter> <type>integer
</type> )
4355 <returnvalue>integer
</returnvalue>
4358 Extracts
<link linkend=
"functions-zerobased-note">n'th
</link> byte
4362 <literal>get_byte('\x1234567890'::bytea,
4)
</literal>
4363 <returnvalue>144</returnvalue>
4368 <entry role=
"func_table_entry"><para role=
"func_signature">
4370 <primary>length
</primary>
4373 <primary>binary string
</primary>
4374 <secondary>length
</secondary>
4377 <primary>length
</primary>
4378 <secondary sortas=
"binary string">of a binary string
</secondary>
4379 <see>binary strings, length
</see>
4381 <function>length
</function> (
<type>bytea
</type> )
4382 <returnvalue>integer
</returnvalue>
4385 Returns the number of bytes in the binary string.
4388 <literal>length('\x1234567890'::bytea)
</literal>
4389 <returnvalue>5</returnvalue>
4394 <entry role=
"func_table_entry"><para role=
"func_signature">
4395 <function>length
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4396 <parameter>encoding
</parameter> <type>name
</type> )
4397 <returnvalue>integer
</returnvalue>
4400 Returns the number of characters in the binary string, assuming
4401 that it is text in the given
<parameter>encoding
</parameter>.
4404 <literal>length('jose'::bytea, 'UTF8')
</literal>
4405 <returnvalue>4</returnvalue>
4410 <entry role=
"func_table_entry"><para role=
"func_signature">
4412 <primary>ltrim
</primary>
4414 <function>ltrim
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4415 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4416 <returnvalue>bytea
</returnvalue>
4419 Removes the longest string containing only bytes appearing in
4420 <parameter>bytesremoved
</parameter> from the start of
4421 <parameter>bytes
</parameter>.
4424 <literal>ltrim('\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4425 <returnvalue>\x34567890
</returnvalue>
4430 <entry role=
"func_table_entry"><para role=
"func_signature">
4432 <primary>md5
</primary>
4434 <function>md5
</function> (
<type>bytea
</type> )
4435 <returnvalue>text
</returnvalue>
4438 Computes the MD5
<link linkend=
"functions-hash-note">hash
</link> of
4439 the binary string, with the result written in hexadecimal.
4442 <literal>md5('Th\
000omas'::bytea)
</literal>
4443 <returnvalue>8ab2d3c9689aaf18
&zwsp;b4958c334c82d8b1
</returnvalue>
4448 <entry role=
"func_table_entry"><para role=
"func_signature">
4450 <primary>rtrim
</primary>
4452 <function>rtrim
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4453 <parameter>bytesremoved
</parameter> <type>bytea
</type> )
4454 <returnvalue>bytea
</returnvalue>
4457 Removes the longest string containing only bytes appearing in
4458 <parameter>bytesremoved
</parameter> from the end of
4459 <parameter>bytes
</parameter>.
4462 <literal>rtrim('\x1234567890'::bytea, '\x9012'::bytea)
</literal>
4463 <returnvalue>\x12345678
</returnvalue>
4468 <entry role=
"func_table_entry"><para role=
"func_signature">
4470 <primary>set_bit
</primary>
4472 <function>set_bit
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4473 <parameter>n
</parameter> <type>bigint
</type>,
4474 <parameter>newvalue
</parameter> <type>integer
</type> )
4475 <returnvalue>bytea
</returnvalue>
4478 Sets
<link linkend=
"functions-zerobased-note">n'th
</link> bit in
4479 binary string to
<parameter>newvalue
</parameter>.
4482 <literal>set_bit('\x1234567890'::bytea,
30,
0)
</literal>
4483 <returnvalue>\x1234563890
</returnvalue>
4488 <entry role=
"func_table_entry"><para role=
"func_signature">
4490 <primary>set_byte
</primary>
4492 <function>set_byte
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4493 <parameter>n
</parameter> <type>integer
</type>,
4494 <parameter>newvalue
</parameter> <type>integer
</type> )
4495 <returnvalue>bytea
</returnvalue>
4498 Sets
<link linkend=
"functions-zerobased-note">n'th
</link> byte in
4499 binary string to
<parameter>newvalue
</parameter>.
4502 <literal>set_byte('\x1234567890'::bytea,
4,
64)
</literal>
4503 <returnvalue>\x1234567840
</returnvalue>
4508 <entry role=
"func_table_entry"><para role=
"func_signature">
4510 <primary>sha224
</primary>
4512 <function>sha224
</function> (
<type>bytea
</type> )
4513 <returnvalue>bytea
</returnvalue>
4516 Computes the SHA-
224 <link linkend=
"functions-hash-note">hash
</link>
4517 of the binary string.
4520 <literal>sha224('abc'::bytea)
</literal>
4521 <returnvalue>\x23097d223405d8228642a477bda2
&zwsp;55b32aadbce4bda0b3f7e36c9da7
</returnvalue>
4526 <entry role=
"func_table_entry"><para role=
"func_signature">
4528 <primary>sha256
</primary>
4530 <function>sha256
</function> (
<type>bytea
</type> )
4531 <returnvalue>bytea
</returnvalue>
4534 Computes the SHA-
256 <link linkend=
"functions-hash-note">hash
</link>
4535 of the binary string.
4538 <literal>sha256('abc'::bytea)
</literal>
4539 <returnvalue>\xba7816bf8f01cfea414140de5dae2223
&zwsp;b00361a396177a9cb410ff61f20015ad
</returnvalue>
4544 <entry role=
"func_table_entry"><para role=
"func_signature">
4546 <primary>sha384
</primary>
4548 <function>sha384
</function> (
<type>bytea
</type> )
4549 <returnvalue>bytea
</returnvalue>
4552 Computes the SHA-
384 <link linkend=
"functions-hash-note">hash
</link>
4553 of the binary string.
4556 <literal>sha384('abc'::bytea)
</literal>
4557 <returnvalue>\xcb00753f45a35e8bb5a03d699ac65007
&zwsp;272c32ab0eded1631a8b605a43ff5bed
&zwsp;8086072ba1e7cc2358baeca134c825a7
</returnvalue>
4562 <entry role=
"func_table_entry"><para role=
"func_signature">
4564 <primary>sha512
</primary>
4566 <function>sha512
</function> (
<type>bytea
</type> )
4567 <returnvalue>bytea
</returnvalue>
4570 Computes the SHA-
512 <link linkend=
"functions-hash-note">hash
</link>
4571 of the binary string.
4574 <literal>sha512('abc'::bytea)
</literal>
4575 <returnvalue>\xddaf35a193617abacc417349ae204131
&zwsp;12e6fa4e89a97ea20a9eeee64b55d39a
&zwsp;2192992a274fc1a836ba3c23a3feebbd
&zwsp;454d4423643ce80e2a9ac94fa54ca49f
</returnvalue>
4580 <entry role=
"func_table_entry"><para role=
"func_signature">
4582 <primary>substr
</primary>
4584 <function>substr
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
<parameter>start
</parameter> <type>integer
</type> <optional>,
<parameter>count
</parameter> <type>integer
</type> </optional> )
4585 <returnvalue>bytea
</returnvalue>
4588 Extracts the substring of
<parameter>bytes
</parameter> starting at
4589 the
<parameter>start
</parameter>'th byte,
4590 and extending for
<parameter>count
</parameter> bytes if that is
4592 as
<literal>substring(
<parameter>bytes
</parameter>
4593 from
<parameter>start
</parameter>
4594 for
<parameter>count
</parameter>)
</literal>.)
4597 <literal>substr('\x1234567890'::bytea,
3,
2)
</literal>
4598 <returnvalue>\x5678
</returnvalue>
4605 <para id=
"functions-zerobased-note">
4606 Functions
<function>get_byte
</function> and
<function>set_byte
</function>
4607 number the first byte of a binary string as byte
0.
4608 Functions
<function>get_bit
</function> and
<function>set_bit
</function>
4609 number bits from the right within each byte; for example bit
0 is the least
4610 significant bit of the first byte, and bit
15 is the most significant bit
4614 <para id=
"functions-hash-note">
4615 For historical reasons, the function
<function>md5
</function>
4616 returns a hex-encoded value of type
<type>text
</type> whereas the SHA-
2
4617 functions return type
<type>bytea
</type>. Use the functions
4618 <link linkend=
"function-encode"><function>encode
</function></link>
4619 and
<link linkend=
"function-decode"><function>decode
</function></link> to
4620 convert between the two. For example write
<literal>encode(sha256('abc'),
4621 'hex')
</literal> to get a hex-encoded text representation,
4622 or
<literal>decode(md5('abc'), 'hex')
</literal> to get
4623 a
<type>bytea
</type> value.
4628 <primary>character string
</primary>
4629 <secondary>converting to binary string
</secondary>
4632 <primary>binary string
</primary>
4633 <secondary>converting to character string
</secondary>
4635 Functions for converting strings between different character sets
4636 (encodings), and for representing arbitrary binary data in textual
4638 <xref linkend=
"functions-binarystring-conversions"/>. For these
4639 functions, an argument or result of type
<type>text
</type> is expressed
4640 in the database's default encoding, while arguments or results of
4641 type
<type>bytea
</type> are in an encoding named by another argument.
4644 <table id=
"functions-binarystring-conversions">
4645 <title>Text/Binary String Conversion Functions
</title>
4649 <entry role=
"func_table_entry"><para role=
"func_signature">
4663 <entry role=
"func_table_entry"><para role=
"func_signature">
4665 <primary>convert
</primary>
4667 <function>convert
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4668 <parameter>src_encoding
</parameter> <type>name
</type>,
4669 <parameter>dest_encoding
</parameter> <type>name
</type> )
4670 <returnvalue>bytea
</returnvalue>
4673 Converts a binary string representing text in
4674 encoding
<parameter>src_encoding
</parameter>
4675 to a binary string in encoding
<parameter>dest_encoding
</parameter>
4676 (see
<xref linkend=
"multibyte-conversions-supported"/> for
4677 available conversions).
4680 <literal>convert('text_in_utf8', 'UTF8', 'LATIN1')
</literal>
4681 <returnvalue>\x746578745f696e5f75746638
</returnvalue>
4686 <entry role=
"func_table_entry"><para role=
"func_signature">
4688 <primary>convert_from
</primary>
4690 <function>convert_from
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4691 <parameter>src_encoding
</parameter> <type>name
</type> )
4692 <returnvalue>text
</returnvalue>
4695 Converts a binary string representing text in
4696 encoding
<parameter>src_encoding
</parameter>
4697 to
<type>text
</type> in the database encoding
4698 (see
<xref linkend=
"multibyte-conversions-supported"/> for
4699 available conversions).
4702 <literal>convert_from('text_in_utf8', 'UTF8')
</literal>
4703 <returnvalue>text_in_utf8
</returnvalue>
4708 <entry role=
"func_table_entry"><para role=
"func_signature">
4710 <primary>convert_to
</primary>
4712 <function>convert_to
</function> (
<parameter>string
</parameter> <type>text
</type>,
4713 <parameter>dest_encoding
</parameter> <type>name
</type> )
4714 <returnvalue>bytea
</returnvalue>
4717 Converts a
<type>text
</type> string (in the database encoding) to a
4718 binary string encoded in encoding
<parameter>dest_encoding
</parameter>
4719 (see
<xref linkend=
"multibyte-conversions-supported"/> for
4720 available conversions).
4723 <literal>convert_to('some_text', 'UTF8')
</literal>
4724 <returnvalue>\x736f6d655f74657874
</returnvalue>
4729 <entry role=
"func_table_entry"><para role=
"func_signature">
4730 <indexterm id=
"function-encode">
4731 <primary>encode
</primary>
4733 <function>encode
</function> (
<parameter>bytes
</parameter> <type>bytea
</type>,
4734 <parameter>format
</parameter> <type>text
</type> )
4735 <returnvalue>text
</returnvalue>
4738 Encodes binary data into a textual representation; supported
4739 <parameter>format
</parameter> values are:
4740 <link linkend=
"encode-format-base64"><literal>base64
</literal></link>,
4741 <link linkend=
"encode-format-escape"><literal>escape
</literal></link>,
4742 <link linkend=
"encode-format-hex"><literal>hex
</literal></link>.
4745 <literal>encode('
123\
000\
001', 'base64')
</literal>
4746 <returnvalue>MTIzAAE=
</returnvalue>
4751 <entry role=
"func_table_entry"><para role=
"func_signature">
4752 <indexterm id=
"function-decode">
4753 <primary>decode
</primary>
4755 <function>decode
</function> (
<parameter>string
</parameter> <type>text
</type>,
4756 <parameter>format
</parameter> <type>text
</type> )
4757 <returnvalue>bytea
</returnvalue>
4760 Decodes binary data from a textual representation; supported
4761 <parameter>format
</parameter> values are the same as
4762 for
<function>encode
</function>.
4765 <literal>decode('MTIzAAE=', 'base64')
</literal>
4766 <returnvalue>\x3132330001
</returnvalue>
4774 The
<function>encode
</function> and
<function>decode
</function>
4775 functions support the following textual formats:
4778 <varlistentry id=
"encode-format-base64">
4781 <primary>base64 format
</primary>
4785 The
<literal>base64
</literal> format is that
4786 of
<ulink url=
"https://tools.ietf.org/html/rfc2045#section-6.8">RFC
4787 2045 Section
6.8</ulink>. As per the
<acronym>RFC
</acronym>, encoded lines are
4788 broken at
76 characters. However instead of the MIME CRLF
4789 end-of-line marker, only a newline is used for end-of-line.
4790 The
<function>decode
</function> function ignores carriage-return,
4791 newline, space, and tab characters. Otherwise, an error is
4792 raised when
<function>decode
</function> is supplied invalid
4793 base64 data
— including when trailing padding is incorrect.
4798 <varlistentry id=
"encode-format-escape">
4801 <primary>escape format
</primary>
4805 The
<literal>escape
</literal> format converts zero bytes and
4806 bytes with the high bit set into octal escape sequences
4807 (
<literal>\
</literal><replaceable>nnn
</replaceable>), and it doubles
4808 backslashes. Other byte values are represented literally.
4809 The
<function>decode
</function> function will raise an error if a
4810 backslash is not followed by either a second backslash or three
4811 octal digits; it accepts other byte values unchanged.
4816 <varlistentry id=
"encode-format-hex">
4819 <primary>hex format
</primary>
4823 The
<literal>hex
</literal> format represents each
4 bits of
4824 data as one hexadecimal digit,
<literal>0</literal>
4825 through
<literal>f
</literal>, writing the higher-order digit of
4826 each byte first. The
<function>encode
</function> function outputs
4827 the
<literal>a
</literal>-
<literal>f
</literal> hex digits in lower
4828 case. Because the smallest unit of data is
8 bits, there are
4829 always an even number of characters returned
4830 by
<function>encode
</function>.
4831 The
<function>decode
</function> function
4832 accepts the
<literal>a
</literal>-
<literal>f
</literal> characters in
4833 either upper or lower case. An error is raised
4834 when
<function>decode
</function> is given invalid hex data
4835 — including when given an odd number of characters.
4843 See also the aggregate function
<function>string_agg
</function> in
4844 <xref linkend=
"functions-aggregate"/> and the large object functions
4845 in
<xref linkend=
"lo-funcs"/>.
4850 <sect1 id=
"functions-bitstring">
4851 <title>Bit String Functions and Operators
</title>
4853 <indexterm zone=
"functions-bitstring">
4854 <primary>bit strings
</primary>
4855 <secondary>functions
</secondary>
4859 This section describes functions and operators for examining and
4860 manipulating bit strings, that is values of the types
4861 <type>bit
</type> and
<type>bit varying
</type>. (While only
4862 type
<type>bit
</type> is mentioned in these tables, values of
4863 type
<type>bit varying
</type> can be used interchangeably.)
4864 Bit strings support the usual comparison operators shown in
4865 <xref linkend=
"functions-comparison-op-table"/>, as well as the
4866 operators shown in
<xref linkend=
"functions-bit-string-op-table"/>.
4869 <table id=
"functions-bit-string-op-table">
4870 <title>Bit String Operators
</title>
4874 <entry role=
"func_table_entry"><para role=
"func_signature">
4888 <entry role=
"func_table_entry"><para role=
"func_signature">
4889 <type>bit
</type> <literal>||
</literal> <type>bit
</type>
4890 <returnvalue>bit
</returnvalue>
4896 <literal>B'
10001' || B'
011'
</literal>
4897 <returnvalue>10001011</returnvalue>
4902 <entry role=
"func_table_entry"><para role=
"func_signature">
4903 <type>bit
</type> <literal>&</literal> <type>bit
</type>
4904 <returnvalue>bit
</returnvalue>
4907 Bitwise AND (inputs must be of equal length)
4910 <literal>B'
10001'
& B'
01101'
</literal>
4911 <returnvalue>00001</returnvalue>
4916 <entry role=
"func_table_entry"><para role=
"func_signature">
4917 <type>bit
</type> <literal>|
</literal> <type>bit
</type>
4918 <returnvalue>bit
</returnvalue>
4921 Bitwise OR (inputs must be of equal length)
4924 <literal>B'
10001' | B'
01101'
</literal>
4925 <returnvalue>11101</returnvalue>
4930 <entry role=
"func_table_entry"><para role=
"func_signature">
4931 <type>bit
</type> <literal>#
</literal> <type>bit
</type>
4932 <returnvalue>bit
</returnvalue>
4935 Bitwise exclusive OR (inputs must be of equal length)
4938 <literal>B'
10001' # B'
01101'
</literal>
4939 <returnvalue>11100</returnvalue>
4944 <entry role=
"func_table_entry"><para role=
"func_signature">
4945 <literal>~
</literal> <type>bit
</type>
4946 <returnvalue>bit
</returnvalue>
4952 <literal>~ B'
10001'
</literal>
4953 <returnvalue>01110</returnvalue>
4958 <entry role=
"func_table_entry"><para role=
"func_signature">
4959 <type>bit
</type> <literal><<</literal> <type>integer
</type>
4960 <returnvalue>bit
</returnvalue>
4964 (string length is preserved)
4967 <literal>B'
10001'
<< 3</literal>
4968 <returnvalue>01000</returnvalue>
4973 <entry role=
"func_table_entry"><para role=
"func_signature">
4974 <type>bit
</type> <literal>>></literal> <type>integer
</type>
4975 <returnvalue>bit
</returnvalue>
4979 (string length is preserved)
4982 <literal>B'
10001'
>> 2</literal>
4983 <returnvalue>00100</returnvalue>
4991 Some of the functions available for binary strings are also available
4992 for bit strings, as shown in
<xref linkend=
"functions-bit-string-table"/>.
4995 <table id=
"functions-bit-string-table">
4996 <title>Bit String Functions
</title>
5000 <entry role=
"func_table_entry"><para role=
"func_signature">
5014 <entry role=
"func_table_entry"><para role=
"func_signature">
5016 <primary>bit_count
</primary>
5018 <function>bit_count
</function> (
<type>bit
</type> )
5019 <returnvalue>bigint
</returnvalue>
5022 Returns the number of bits set in the bit string (also known as
5023 <quote>popcount
</quote>).
5026 <literal>bit_count(B'
10111')
</literal>
5027 <returnvalue>4</returnvalue>
5032 <entry role=
"func_table_entry"><para role=
"func_signature">
5034 <primary>bit_length
</primary>
5036 <function>bit_length
</function> (
<type>bit
</type> )
5037 <returnvalue>integer
</returnvalue>
5040 Returns number of bits in the bit string.
5043 <literal>bit_length(B'
10111')
</literal>
5044 <returnvalue>5</returnvalue>
5049 <entry role=
"func_table_entry"><para role=
"func_signature">
5051 <primary>length
</primary>
5054 <primary>bit string
</primary>
5055 <secondary>length
</secondary>
5057 <function>length
</function> (
<type>bit
</type> )
5058 <returnvalue>integer
</returnvalue>
5061 Returns number of bits in the bit string.
5064 <literal>length(B'
10111')
</literal>
5065 <returnvalue>5</returnvalue>
5070 <entry role=
"func_table_entry"><para role=
"func_signature">
5072 <primary>octet_length
</primary>
5074 <function>octet_length
</function> (
<type>bit
</type> )
5075 <returnvalue>integer
</returnvalue>
5078 Returns number of bytes in the bit string.
5081 <literal>octet_length(B'
1011111011')
</literal>
5082 <returnvalue>2</returnvalue>
5087 <entry role=
"func_table_entry"><para role=
"func_signature">
5089 <primary>overlay
</primary>
5091 <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> )
5092 <returnvalue>bit
</returnvalue>
5095 Replaces the substring of
<parameter>bits
</parameter> that starts at
5096 the
<parameter>start
</parameter>'th bit and extends
5097 for
<parameter>count
</parameter> bits
5098 with
<parameter>newsubstring
</parameter>.
5099 If
<parameter>count
</parameter> is omitted, it defaults to the length
5100 of
<parameter>newsubstring
</parameter>.
5103 <literal>overlay(B'
01010101010101010' placing B'
11111' from
2 for
3)
</literal>
5104 <returnvalue>0111110101010101010</returnvalue>
5109 <entry role=
"func_table_entry"><para role=
"func_signature">
5111 <primary>position
</primary>
5113 <function>position
</function> (
<parameter>substring
</parameter> <type>bit
</type> <literal>IN
</literal> <parameter>bits
</parameter> <type>bit
</type> )
5114 <returnvalue>integer
</returnvalue>
5117 Returns first starting index of the specified
<parameter>substring
</parameter>
5118 within
<parameter>bits
</parameter>, or zero if it's not present.
5121 <literal>position(B'
010' in B'
000001101011')
</literal>
5122 <returnvalue>8</returnvalue>
5127 <entry role=
"func_table_entry"><para role=
"func_signature">
5129 <primary>substring
</primary>
5131 <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> )
5132 <returnvalue>bit
</returnvalue>
5135 Extracts the substring of
<parameter>bits
</parameter> starting at
5136 the
<parameter>start
</parameter>'th bit if that is specified,
5137 and stopping after
<parameter>count
</parameter> bits if that is
5138 specified. Provide at least one of
<parameter>start
</parameter>
5139 and
<parameter>count
</parameter>.
5142 <literal>substring(B'
110010111111' from
3 for
2)
</literal>
5143 <returnvalue>00</returnvalue>
5148 <entry role=
"func_table_entry"><para role=
"func_signature">
5150 <primary>get_bit
</primary>
5152 <function>get_bit
</function> (
<parameter>bits
</parameter> <type>bit
</type>,
5153 <parameter>n
</parameter> <type>integer
</type> )
5154 <returnvalue>integer
</returnvalue>
5157 Extracts
<parameter>n
</parameter>'th bit
5158 from bit string; the first (leftmost) bit is bit
0.
5161 <literal>get_bit(B'
101010101010101010',
6)
</literal>
5162 <returnvalue>1</returnvalue>
5167 <entry role=
"func_table_entry"><para role=
"func_signature">
5169 <primary>set_bit
</primary>
5171 <function>set_bit
</function> (
<parameter>bits
</parameter> <type>bit
</type>,
5172 <parameter>n
</parameter> <type>integer
</type>,
5173 <parameter>newvalue
</parameter> <type>integer
</type> )
5174 <returnvalue>bit
</returnvalue>
5177 Sets
<parameter>n
</parameter>'th bit in
5178 bit string to
<parameter>newvalue
</parameter>;
5179 the first (leftmost) bit is bit
0.
5182 <literal>set_bit(B'
101010101010101010',
6,
0)
</literal>
5183 <returnvalue>101010001010101010</returnvalue>
5191 In addition, it is possible to cast integral values to and from type
5193 Casting an integer to
<type>bit(n)
</type> copies the rightmost
5194 <literal>n
</literal> bits. Casting an integer to a bit string width wider
5195 than the integer itself will sign-extend on the left.
5198 44::bit(
10)
<lineannotation>0000101100</lineannotation>
5199 44::bit(
3)
<lineannotation>100</lineannotation>
5200 cast(-
44 as bit(
12))
<lineannotation>111111010100</lineannotation>
5201 '
1110'::bit(
4)::integer
<lineannotation>14</lineannotation>
5203 Note that casting to just
<quote>bit
</quote> means casting to
5204 <literal>bit(
1)
</literal>, and so will deliver only the least significant
5210 <sect1 id=
"functions-matching">
5211 <title>Pattern Matching
</title>
5213 <indexterm zone=
"functions-matching">
5214 <primary>pattern matching
</primary>
5218 There are three separate approaches to pattern matching provided
5219 by
<productname>PostgreSQL
</productname>: the traditional
5220 <acronym>SQL
</acronym> <function>LIKE
</function> operator, the
5221 more recent
<function>SIMILAR TO
</function> operator (added in
5222 SQL:
1999), and
<acronym>POSIX
</acronym>-style regular
5223 expressions. Aside from the basic
<quote>does this string match
5224 this pattern?
</quote> operators, functions are available to extract
5225 or replace matching substrings and to split a string at matching
5231 If you have pattern matching needs that go beyond this,
5232 consider writing a user-defined function in Perl or Tcl.
5238 While most regular-expression searches can be executed very quickly,
5239 regular expressions can be contrived that take arbitrary amounts of
5240 time and memory to process. Be wary of accepting regular-expression
5241 search patterns from hostile sources. If you must do so, it is
5242 advisable to impose a statement timeout.
5246 Searches using
<function>SIMILAR TO
</function> patterns have the same
5247 security hazards, since
<function>SIMILAR TO
</function> provides many
5248 of the same capabilities as
<acronym>POSIX
</acronym>-style regular
5253 <function>LIKE
</function> searches, being much simpler than the other
5254 two options, are safer to use with possibly-hostile pattern sources.
5259 The pattern matching operators of all three kinds do not support
5260 nondeterministic collations. If required, apply a different collation to
5261 the expression to work around this limitation.
5264 <sect2 id=
"functions-like">
5265 <title><function>LIKE
</function></title>
5268 <primary>LIKE
</primary>
5272 <replaceable>string
</replaceable> LIKE
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5273 <replaceable>string
</replaceable> NOT LIKE
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5277 The
<function>LIKE
</function> expression returns true if the
5278 <replaceable>string
</replaceable> matches the supplied
5279 <replaceable>pattern
</replaceable>. (As
5280 expected, the
<function>NOT LIKE
</function> expression returns
5281 false if
<function>LIKE
</function> returns true, and vice versa.
5282 An equivalent expression is
5283 <literal>NOT (
<replaceable>string
</replaceable> LIKE
5284 <replaceable>pattern
</replaceable>)
</literal>.)
5288 If
<replaceable>pattern
</replaceable> does not contain percent
5289 signs or underscores, then the pattern only represents the string
5290 itself; in that case
<function>LIKE
</function> acts like the
5291 equals operator. An underscore (
<literal>_
</literal>) in
5292 <replaceable>pattern
</replaceable> stands for (matches) any single
5293 character; a percent sign (
<literal>%
</literal>) matches any sequence
5294 of zero or more characters.
5300 'abc' LIKE 'abc'
<lineannotation>true
</lineannotation>
5301 'abc' LIKE 'a%'
<lineannotation>true
</lineannotation>
5302 'abc' LIKE '_b_'
<lineannotation>true
</lineannotation>
5303 'abc' LIKE 'c'
<lineannotation>false
</lineannotation>
5308 <function>LIKE
</function> pattern matching always covers the entire
5309 string. Therefore, if it's desired to match a sequence anywhere within
5310 a string, the pattern must start and end with a percent sign.
5314 To match a literal underscore or percent sign without matching
5315 other characters, the respective character in
5316 <replaceable>pattern
</replaceable> must be
5317 preceded by the escape character. The default escape
5318 character is the backslash but a different one can be selected by
5319 using the
<literal>ESCAPE
</literal> clause. To match the escape
5320 character itself, write two escape characters.
5325 If you have
<xref linkend=
"guc-standard-conforming-strings"/> turned off,
5326 any backslashes you write in literal string constants will need to be
5327 doubled. See
<xref linkend=
"sql-syntax-strings"/> for more information.
5332 It's also possible to select no escape character by writing
5333 <literal>ESCAPE ''
</literal>. This effectively disables the
5334 escape mechanism, which makes it impossible to turn off the
5335 special meaning of underscore and percent signs in the pattern.
5339 According to the SQL standard, omitting
<literal>ESCAPE
</literal>
5340 means there is no escape character (rather than defaulting to a
5341 backslash), and a zero-length
<literal>ESCAPE
</literal> value is
5342 disallowed.
<productname>PostgreSQL
</productname>'s behavior in
5343 this regard is therefore slightly nonstandard.
5347 The key word
<token>ILIKE
</token> can be used instead of
5348 <token>LIKE
</token> to make the match case-insensitive according
5349 to the active locale. This is not in the
<acronym>SQL
</acronym> standard but is a
5350 <productname>PostgreSQL
</productname> extension.
5354 The operator
<literal>~~
</literal> is equivalent to
5355 <function>LIKE
</function>, and
<literal>~~*
</literal> corresponds to
5356 <function>ILIKE
</function>. There are also
5357 <literal>!~~
</literal> and
<literal>!~~*
</literal> operators that
5358 represent
<function>NOT LIKE
</function> and
<function>NOT
5359 ILIKE
</function>, respectively. All of these operators are
5360 <productname>PostgreSQL
</productname>-specific. You may see these
5361 operator names in
<command>EXPLAIN
</command> output and similar
5362 places, since the parser actually translates
<function>LIKE
</function>
5363 et al. to these operators.
5367 The phrases
<function>LIKE
</function>,
<function>ILIKE
</function>,
5368 <function>NOT LIKE
</function>, and
<function>NOT ILIKE
</function> are
5369 generally treated as operators
5370 in
<productname>PostgreSQL
</productname> syntax; for example they can
5371 be used in
<replaceable>expression
</replaceable>
5372 <replaceable>operator
</replaceable> ANY
5373 (
<replaceable>subquery
</replaceable>) constructs, although
5374 an
<literal>ESCAPE
</literal> clause cannot be included there. In some
5375 obscure cases it may be necessary to use the underlying operator names
5380 Also see the starts-with operator
<literal>^@
</literal> and the
5381 corresponding
<function>starts_with()
</function> function, which are
5382 useful in cases where simply matching the beginning of a string is
5388 <sect2 id=
"functions-similarto-regexp">
5389 <title><function>SIMILAR TO
</function> Regular Expressions
</title>
5392 <primary>regular expression
</primary>
5393 <!-- <seealso>pattern matching</seealso> breaks index build -->
5397 <primary>SIMILAR TO
</primary>
5400 <primary>substring
</primary>
5404 <replaceable>string
</replaceable> SIMILAR TO
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5405 <replaceable>string
</replaceable> NOT SIMILAR TO
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
5409 The
<function>SIMILAR TO
</function> operator returns true or
5410 false depending on whether its pattern matches the given string.
5411 It is similar to
<function>LIKE
</function>, except that it
5412 interprets the pattern using the SQL standard's definition of a
5413 regular expression. SQL regular expressions are a curious cross
5414 between
<function>LIKE
</function> notation and common (POSIX) regular
5415 expression notation.
5419 Like
<function>LIKE
</function>, the
<function>SIMILAR TO
</function>
5420 operator succeeds only if its pattern matches the entire string;
5421 this is unlike common regular expression behavior where the pattern
5422 can match any part of the string.
5424 <function>LIKE
</function>,
<function>SIMILAR TO
</function> uses
5425 <literal>_
</literal> and
<literal>%
</literal> as wildcard characters denoting
5426 any single character and any string, respectively (these are
5427 comparable to
<literal>.
</literal> and
<literal>.*
</literal> in POSIX regular
5432 In addition to these facilities borrowed from
<function>LIKE
</function>,
5433 <function>SIMILAR TO
</function> supports these pattern-matching
5434 metacharacters borrowed from POSIX regular expressions:
5439 <literal>|
</literal> denotes alternation (either of two alternatives).
5444 <literal>*
</literal> denotes repetition of the previous item zero
5450 <literal>+
</literal> denotes repetition of the previous item one
5456 <literal>?
</literal> denotes repetition of the previous item zero
5462 <literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal> denotes repetition
5463 of the previous item exactly
<replaceable>m
</replaceable> times.
5468 <literal>{
</literal><replaceable>m
</replaceable><literal>,}
</literal> denotes repetition
5469 of the previous item
<replaceable>m
</replaceable> or more times.
5474 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal>
5475 denotes repetition of the previous item at least
<replaceable>m
</replaceable> and
5476 not more than
<replaceable>n
</replaceable> times.
5481 Parentheses
<literal>()
</literal> can be used to group items into
5482 a single logical item.
5487 A bracket expression
<literal>[...]
</literal> specifies a character
5488 class, just as in POSIX regular expressions.
5493 Notice that the period (
<literal>.
</literal>) is not a metacharacter
5494 for
<function>SIMILAR TO
</function>.
5498 As with
<function>LIKE
</function>, a backslash disables the special
5499 meaning of any of these metacharacters. A different escape character
5500 can be specified with
<literal>ESCAPE
</literal>, or the escape
5501 capability can be disabled by writing
<literal>ESCAPE ''
</literal>.
5505 According to the SQL standard, omitting
<literal>ESCAPE
</literal>
5506 means there is no escape character (rather than defaulting to a
5507 backslash), and a zero-length
<literal>ESCAPE
</literal> value is
5508 disallowed.
<productname>PostgreSQL
</productname>'s behavior in
5509 this regard is therefore slightly nonstandard.
5513 Another nonstandard extension is that following the escape character
5514 with a letter or digit provides access to the escape sequences
5515 defined for POSIX regular expressions; see
5516 <xref linkend=
"posix-character-entry-escapes-table"/>,
5517 <xref linkend=
"posix-class-shorthand-escapes-table"/>, and
5518 <xref linkend=
"posix-constraint-escapes-table"/> below.
5524 'abc' SIMILAR TO 'abc'
<lineannotation>true
</lineannotation>
5525 'abc' SIMILAR TO 'a'
<lineannotation>false
</lineannotation>
5526 'abc' SIMILAR TO '%(b|d)%'
<lineannotation>true
</lineannotation>
5527 'abc' SIMILAR TO '(b|c)%'
<lineannotation>false
</lineannotation>
5528 '-abc-' SIMILAR TO '%\mabc\M%'
<lineannotation>true
</lineannotation>
5529 'xabcy' SIMILAR TO '%\mabc\M%'
<lineannotation>false
</lineannotation>
5534 The
<function>substring
</function> function with three parameters
5535 provides extraction of a substring that matches an SQL
5536 regular expression pattern. The function can be written according
5537 to standard SQL syntax:
5539 substring(
<replaceable>string
</replaceable> similar
<replaceable>pattern
</replaceable> escape
<replaceable>escape-character
</replaceable>)
5541 or using the now obsolete SQL:
1999 syntax:
5543 substring(
<replaceable>string
</replaceable> from
<replaceable>pattern
</replaceable> for
<replaceable>escape-character
</replaceable>)
5545 or as a plain three-argument function:
5547 substring(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>,
<replaceable>escape-character
</replaceable>)
5549 As with
<literal>SIMILAR TO
</literal>, the
5550 specified pattern must match the entire data string, or else the
5551 function fails and returns null. To indicate the part of the
5552 pattern for which the matching data sub-string is of interest,
5553 the pattern should contain
5554 two occurrences of the escape character followed by a double quote
5555 (
<literal>"</literal>). <!-- " font-lock sanity -->
5556 The text matching the portion of the pattern
5557 between these separators is returned when the match is successful.
5561 The escape-double-quote separators actually
5562 divide
<function>substring
</function>'s pattern into three independent
5563 regular expressions; for example, a vertical bar (
<literal>|
</literal>)
5564 in any of the three sections affects only that section. Also, the first
5565 and third of these regular expressions are defined to match the smallest
5566 possible amount of text, not the largest, when there is any ambiguity
5567 about how much of the data string matches which pattern. (In POSIX
5568 parlance, the first and third regular expressions are forced to be
5573 As an extension to the SQL standard,
<productname>PostgreSQL
</productname>
5574 allows there to be just one escape-double-quote separator, in which case
5575 the third regular expression is taken as empty; or no separators, in which
5576 case the first and third regular expressions are taken as empty.
5580 Some examples, with
<literal>#
"</literal> delimiting the return string:
5582 substring('foobar' similar '%#
"o_b#"%' escape '#')
<lineannotation>oob
</lineannotation>
5583 substring('foobar' similar '#
"o_b#"%' escape '#')
<lineannotation>NULL
</lineannotation>
5588 <sect2 id=
"functions-posix-regexp">
5589 <title><acronym>POSIX
</acronym> Regular Expressions
</title>
5591 <indexterm zone=
"functions-posix-regexp">
5592 <primary>regular expression
</primary>
5593 <seealso>pattern matching
</seealso>
5596 <primary>substring
</primary>
5599 <primary>regexp_count
</primary>
5602 <primary>regexp_instr
</primary>
5605 <primary>regexp_like
</primary>
5608 <primary>regexp_match
</primary>
5611 <primary>regexp_matches
</primary>
5614 <primary>regexp_replace
</primary>
5617 <primary>regexp_split_to_table
</primary>
5620 <primary>regexp_split_to_array
</primary>
5623 <primary>regexp_substr
</primary>
5627 <xref linkend=
"functions-posix-table"/> lists the available
5628 operators for pattern matching using POSIX regular expressions.
5631 <table id=
"functions-posix-table">
5632 <title>Regular Expression Match Operators
</title>
5637 <entry role=
"func_table_entry"><para role=
"func_signature">
5651 <entry role=
"func_table_entry"><para role=
"func_signature">
5652 <type>text
</type> <literal>~
</literal> <type>text
</type>
5653 <returnvalue>boolean
</returnvalue>
5656 String matches regular expression, case sensitively
5659 <literal>'thomas' ~ 't.*ma'
</literal>
5660 <returnvalue>t
</returnvalue>
5665 <entry role=
"func_table_entry"><para role=
"func_signature">
5666 <type>text
</type> <literal>~*
</literal> <type>text
</type>
5667 <returnvalue>boolean
</returnvalue>
5670 String matches regular expression, case-insensitively
5673 <literal>'thomas' ~* 'T.*ma'
</literal>
5674 <returnvalue>t
</returnvalue>
5679 <entry role=
"func_table_entry"><para role=
"func_signature">
5680 <type>text
</type> <literal>!~
</literal> <type>text
</type>
5681 <returnvalue>boolean
</returnvalue>
5684 String does not match regular expression, case sensitively
5687 <literal>'thomas' !~ 't.*max'
</literal>
5688 <returnvalue>t
</returnvalue>
5693 <entry role=
"func_table_entry"><para role=
"func_signature">
5694 <type>text
</type> <literal>!~*
</literal> <type>text
</type>
5695 <returnvalue>boolean
</returnvalue>
5698 String does not match regular expression, case-insensitively
5701 <literal>'thomas' !~* 'T.*ma'
</literal>
5702 <returnvalue>f
</returnvalue>
5710 <acronym>POSIX
</acronym> regular expressions provide a more
5711 powerful means for pattern matching than the
<function>LIKE
</function> and
5712 <function>SIMILAR TO
</function> operators.
5713 Many Unix tools such as
<command>egrep
</command>,
5714 <command>sed
</command>, or
<command>awk
</command> use a pattern
5715 matching language that is similar to the one described here.
5719 A regular expression is a character sequence that is an
5720 abbreviated definition of a set of strings (a
<firstterm>regular
5721 set
</firstterm>). A string is said to match a regular expression
5722 if it is a member of the regular set described by the regular
5723 expression. As with
<function>LIKE
</function>, pattern characters
5724 match string characters exactly unless they are special characters
5725 in the regular expression language
— but regular expressions use
5726 different special characters than
<function>LIKE
</function> does.
5727 Unlike
<function>LIKE
</function> patterns, a
5728 regular expression is allowed to match anywhere within a string, unless
5729 the regular expression is explicitly anchored to the beginning or
5736 'abcd' ~ 'bc'
<lineannotation>true
</lineannotation>
5737 'abcd' ~ 'a.c'
<lineannotation>true
— dot matches any character
</lineannotation>
5738 'abcd' ~ 'a.*d'
<lineannotation>true
— <literal>*
</literal> repeats the preceding pattern item
</lineannotation>
5739 'abcd' ~ '(b|x)'
<lineannotation>true
— <literal>|
</literal> means OR, parentheses group
</lineannotation>
5740 'abcd' ~ '^a'
<lineannotation>true
— <literal>^
</literal> anchors to start of string
</lineannotation>
5741 'abcd' ~ '^(b|c)'
<lineannotation>false
— would match except for anchoring
</lineannotation>
5746 The
<acronym>POSIX
</acronym> pattern language is described in much
5747 greater detail below.
5751 The
<function>substring
</function> function with two parameters,
5752 <function>substring(
<replaceable>string
</replaceable> from
5753 <replaceable>pattern
</replaceable>)
</function>, provides extraction of a
5755 that matches a POSIX regular expression pattern. It returns null if
5756 there is no match, otherwise the first portion of the text that matched the
5757 pattern. But if the pattern contains any parentheses, the portion
5758 of the text that matched the first parenthesized subexpression (the
5759 one whose left parenthesis comes first) is
5760 returned. You can put parentheses around the whole expression
5761 if you want to use parentheses within it without triggering this
5762 exception. If you need parentheses in the pattern before the
5763 subexpression you want to extract, see the non-capturing parentheses
5770 substring('foobar' from 'o.b')
<lineannotation>oob
</lineannotation>
5771 substring('foobar' from 'o(.)b')
<lineannotation>o
</lineannotation>
5776 The
<function>regexp_count
</function> function counts the number of
5777 places where a POSIX regular expression pattern matches a string.
5779 <function>regexp_count
</function>(
<replaceable>string
</replaceable>,
5780 <replaceable>pattern
</replaceable>
5781 <optional>,
<replaceable>start
</replaceable>
5782 <optional>,
<replaceable>flags
</replaceable>
5783 </optional></optional>).
5784 <replaceable>pattern
</replaceable> is searched for
5785 in
<replaceable>string
</replaceable>, normally from the beginning of
5786 the string, but if the
<replaceable>start
</replaceable> parameter is
5787 provided then beginning from that character index.
5788 The
<replaceable>flags
</replaceable> parameter is an optional text
5789 string containing zero or more single-letter flags that change the
5790 function's behavior. For example, including
<literal>i
</literal> in
5791 <replaceable>flags
</replaceable> specifies case-insensitive matching.
5792 Supported flags are described in
5793 <xref linkend=
"posix-embedded-options-table"/>.
5799 regexp_count('ABCABCAXYaxy', 'A.')
<lineannotation>3</lineannotation>
5800 regexp_count('ABCABCAXYaxy', 'A.',
1, 'i')
<lineannotation>4</lineannotation>
5805 The
<function>regexp_instr
</function> function returns the starting or
5806 ending position of the
<replaceable>N
</replaceable>'th match of a
5807 POSIX regular expression pattern to a string, or zero if there is no
5808 such match. It has the syntax
5809 <function>regexp_instr
</function>(
<replaceable>string
</replaceable>,
5810 <replaceable>pattern
</replaceable>
5811 <optional>,
<replaceable>start
</replaceable>
5812 <optional>,
<replaceable>N
</replaceable>
5813 <optional>,
<replaceable>endoption
</replaceable>
5814 <optional>,
<replaceable>flags
</replaceable>
5815 <optional>,
<replaceable>subexpr
</replaceable>
5816 </optional></optional></optional></optional></optional>).
5817 <replaceable>pattern
</replaceable> is searched for
5818 in
<replaceable>string
</replaceable>, normally from the beginning of
5819 the string, but if the
<replaceable>start
</replaceable> parameter is
5820 provided then beginning from that character index.
5821 If
<replaceable>N
</replaceable> is specified
5822 then the
<replaceable>N
</replaceable>'th match of the pattern
5823 is located, otherwise the first match is located.
5824 If the
<replaceable>endoption
</replaceable> parameter is omitted or
5825 specified as zero, the function returns the position of the first
5826 character of the match. Otherwise,
<replaceable>endoption
</replaceable>
5827 must be one, and the function returns the position of the character
5828 following the match.
5829 The
<replaceable>flags
</replaceable> parameter is an optional text
5830 string containing zero or more single-letter flags that change the
5831 function's behavior. Supported flags are described
5832 in
<xref linkend=
"posix-embedded-options-table"/>.
5833 For a pattern containing parenthesized
5834 subexpressions,
<replaceable>subexpr
</replaceable> is an integer
5835 indicating which subexpression is of interest: the result identifies
5836 the position of the substring matching that subexpression.
5837 Subexpressions are numbered in the order of their leading parentheses.
5838 When
<replaceable>subexpr
</replaceable> is omitted or zero, the result
5839 identifies the position of the whole match regardless of
5840 parenthesized subexpressions.
5846 regexp_instr('number of your street, town zip, FR', '[^,]+',
1,
2)
5847 <lineannotation>23</lineannotation>
5848 regexp_instr('ABCDEFGHI', '(c..)(...)',
1,
1,
0, 'i',
2)
5849 <lineannotation>6</lineannotation>
5854 The
<function>regexp_like
</function> function checks whether a match
5855 of a POSIX regular expression pattern occurs within a string,
5856 returning boolean true or false. It has the syntax
5857 <function>regexp_like
</function>(
<replaceable>string
</replaceable>,
5858 <replaceable>pattern
</replaceable>
5859 <optional>,
<replaceable>flags
</replaceable> </optional>).
5860 The
<replaceable>flags
</replaceable> parameter is an optional text
5861 string containing zero or more single-letter flags that change the
5862 function's behavior. Supported flags are described
5863 in
<xref linkend=
"posix-embedded-options-table"/>.
5864 This function has the same results as the
<literal>~
</literal>
5865 operator if no flags are specified. If only the
<literal>i
</literal>
5866 flag is specified, it has the same results as
5867 the
<literal>~*
</literal> operator.
5873 regexp_like('Hello World', 'world')
<lineannotation>false
</lineannotation>
5874 regexp_like('Hello World', 'world', 'i')
<lineannotation>true
</lineannotation>
5879 The
<function>regexp_match
</function> function returns a text array of
5880 matching substring(s) within the first match of a POSIX
5881 regular expression pattern to a string. It has the syntax
5882 <function>regexp_match
</function>(
<replaceable>string
</replaceable>,
5883 <replaceable>pattern
</replaceable> <optional>,
<replaceable>flags
</replaceable> </optional>).
5884 If there is no match, the result is
<literal>NULL
</literal>.
5885 If a match is found, and the
<replaceable>pattern
</replaceable> contains no
5886 parenthesized subexpressions, then the result is a single-element text
5887 array containing the substring matching the whole pattern.
5888 If a match is found, and the
<replaceable>pattern
</replaceable> contains
5889 parenthesized subexpressions, then the result is a text array
5890 whose
<replaceable>n
</replaceable>'th element is the substring matching
5891 the
<replaceable>n
</replaceable>'th parenthesized subexpression of
5892 the
<replaceable>pattern
</replaceable> (not counting
<quote>non-capturing
</quote>
5893 parentheses; see below for details).
5894 The
<replaceable>flags
</replaceable> parameter is an optional text string
5895 containing zero or more single-letter flags that change the function's
5896 behavior. Supported flags are described
5897 in
<xref linkend=
"posix-embedded-options-table"/>.
5903 SELECT regexp_match('foobarbequebaz', 'bar.*que');
5909 SELECT regexp_match('foobarbequebaz', '(bar)(beque)');
5919 In the common case where you just want the whole matching substring
5920 or
<literal>NULL
</literal> for no match, the best solution is to
5921 use
<function>regexp_substr()
</function>.
5922 However,
<function>regexp_substr()
</function> only exists
5923 in
<productname>PostgreSQL
</productname> version
15 and up. When
5924 working in older versions, you can extract the first element
5925 of
<function>regexp_match()
</function>'s result, for example:
5927 SELECT (regexp_match('foobarbequebaz', 'bar.*que'))[
1];
5937 The
<function>regexp_matches
</function> function returns a set of text arrays
5938 of matching substring(s) within matches of a POSIX regular
5939 expression pattern to a string. It has the same syntax as
5940 <function>regexp_match
</function>.
5941 This function returns no rows if there is no match, one row if there is
5942 a match and the
<literal>g
</literal> flag is not given, or
<replaceable>N
</replaceable>
5943 rows if there are
<replaceable>N
</replaceable> matches and the
<literal>g
</literal> flag
5944 is given. Each returned row is a text array containing the whole
5945 matched substring or the substrings matching parenthesized
5946 subexpressions of the
<replaceable>pattern
</replaceable>, just as described above
5947 for
<function>regexp_match
</function>.
5948 <function>regexp_matches
</function> accepts all the flags shown
5949 in
<xref linkend=
"posix-embedded-options-table"/>, plus
5950 the
<literal>g
</literal> flag which commands it to return all matches, not
5957 SELECT regexp_matches('foo', 'not there');
5962 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
5973 In most cases
<function>regexp_matches()
</function> should be used with
5974 the
<literal>g
</literal> flag, since if you only want the first match, it's
5975 easier and more efficient to use
<function>regexp_match()
</function>.
5976 However,
<function>regexp_match()
</function> only exists
5977 in
<productname>PostgreSQL
</productname> version
10 and up. When working in older
5978 versions, a common trick is to place a
<function>regexp_matches()
</function>
5979 call in a sub-select, for example:
5981 SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
5983 This produces a text array if there's a match, or
<literal>NULL
</literal> if
5984 not, the same as
<function>regexp_match()
</function> would do. Without the
5985 sub-select, this query would produce no output at all for table rows
5986 without a match, which is typically not the desired behavior.
5991 The
<function>regexp_replace
</function> function provides substitution of
5992 new text for substrings that match POSIX regular expression patterns.
5994 <function>regexp_replace
</function>(
<replaceable>source
</replaceable>,
5995 <replaceable>pattern
</replaceable>,
<replaceable>replacement
</replaceable>
5996 <optional>,
<replaceable>start
</replaceable>
5997 <optional>,
<replaceable>N
</replaceable>
5998 </optional></optional>
5999 <optional>,
<replaceable>flags
</replaceable> </optional>).
6000 (Notice that
<replaceable>N
</replaceable> cannot be specified
6001 unless
<replaceable>start
</replaceable> is,
6002 but
<replaceable>flags
</replaceable> can be given in any case.)
6003 The
<replaceable>source
</replaceable> string is returned unchanged if
6004 there is no match to the
<replaceable>pattern
</replaceable>. If there is a
6005 match, the
<replaceable>source
</replaceable> string is returned with the
6006 <replaceable>replacement
</replaceable> string substituted for the matching
6007 substring. The
<replaceable>replacement
</replaceable> string can contain
6008 <literal>\
</literal><replaceable>n
</replaceable>, where
<replaceable>n
</replaceable> is
1
6009 through
9, to indicate that the source substring matching the
6010 <replaceable>n
</replaceable>'th parenthesized subexpression of the pattern should be
6011 inserted, and it can contain
<literal>\
&</literal> to indicate that the
6012 substring matching the entire pattern should be inserted. Write
6013 <literal>\\
</literal> if you need to put a literal backslash in the replacement
6015 <replaceable>pattern
</replaceable> is searched for
6016 in
<replaceable>string
</replaceable>, normally from the beginning of
6017 the string, but if the
<replaceable>start
</replaceable> parameter is
6018 provided then beginning from that character index.
6019 By default, only the first match of the pattern is replaced.
6020 If
<replaceable>N
</replaceable> is specified and is greater than zero,
6021 then the
<replaceable>N
</replaceable>'th match of the pattern
6023 If the
<literal>g
</literal> flag is given, or
6024 if
<replaceable>N
</replaceable> is specified and is zero, then all
6025 matches at or after the
<replaceable>start
</replaceable> position are
6026 replaced. (The
<literal>g
</literal> flag is ignored
6027 when
<replaceable>N
</replaceable> is specified.)
6028 The
<replaceable>flags
</replaceable> parameter is an optional text
6029 string containing zero or more single-letter flags that change the
6030 function's behavior. Supported flags (though
6031 not
<literal>g
</literal>) are
6032 described in
<xref linkend=
"posix-embedded-options-table"/>.
6038 regexp_replace('foobarbaz', 'b..', 'X')
6039 <lineannotation>fooXbaz
</lineannotation>
6040 regexp_replace('foobarbaz', 'b..', 'X', 'g')
6041 <lineannotation>fooXX
</lineannotation>
6042 regexp_replace('foobarbaz', 'b(..)', 'X\
1Y', 'g')
6043 <lineannotation>fooXarYXazY
</lineannotation>
6044 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X',
1,
0, 'i')
6045 <lineannotation>X PXstgrXSQL fXnctXXn
</lineannotation>
6046 regexp_replace('A PostgreSQL function', 'a|e|i|o|u', 'X',
1,
3, 'i')
6047 <lineannotation>A PostgrXSQL function
</lineannotation>
6052 The
<function>regexp_split_to_table
</function> function splits a string using a POSIX
6053 regular expression pattern as a delimiter. It has the syntax
6054 <function>regexp_split_to_table
</function>(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>
6055 <optional>,
<replaceable>flags
</replaceable> </optional>).
6056 If there is no match to the
<replaceable>pattern
</replaceable>, the function returns the
6057 <replaceable>string
</replaceable>. If there is at least one match, for each match it returns
6058 the text from the end of the last match (or the beginning of the string)
6059 to the beginning of the match. When there are no more matches, it
6060 returns the text from the end of the last match to the end of the string.
6061 The
<replaceable>flags
</replaceable> parameter is an optional text string containing
6062 zero or more single-letter flags that change the function's behavior.
6063 <function>regexp_split_to_table
</function> supports the flags described in
6064 <xref linkend=
"posix-embedded-options-table"/>.
6068 The
<function>regexp_split_to_array
</function> function behaves the same as
6069 <function>regexp_split_to_table
</function>, except that
<function>regexp_split_to_array
</function>
6070 returns its result as an array of
<type>text
</type>. It has the syntax
6071 <function>regexp_split_to_array
</function>(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>
6072 <optional>,
<replaceable>flags
</replaceable> </optional>).
6073 The parameters are the same as for
<function>regexp_split_to_table
</function>.
6079 SELECT foo FROM regexp_split_to_table('the quick brown fox jumps over the lazy dog', '\s+') AS foo;
6093 SELECT regexp_split_to_array('the quick brown fox jumps over the lazy dog', '\s+');
6094 regexp_split_to_array
6095 -----------------------------------------------
6096 {the,quick,brown,fox,jumps,over,the,lazy,dog}
6099 SELECT foo FROM regexp_split_to_table('the quick brown fox', '\s*') AS foo;
6123 As the last example demonstrates, the regexp split functions ignore
6124 zero-length matches that occur at the start or end of the string
6125 or immediately after a previous match. This is contrary to the strict
6126 definition of regexp matching that is implemented by
6127 the other regexp functions, but is usually the most convenient behavior
6128 in practice. Other software systems such as Perl use similar definitions.
6132 The
<function>regexp_substr
</function> function returns the substring
6133 that matches a POSIX regular expression pattern,
6134 or
<literal>NULL
</literal> if there is no match. It has the syntax
6135 <function>regexp_substr
</function>(
<replaceable>string
</replaceable>,
6136 <replaceable>pattern
</replaceable>
6137 <optional>,
<replaceable>start
</replaceable>
6138 <optional>,
<replaceable>N
</replaceable>
6139 <optional>,
<replaceable>flags
</replaceable>
6140 <optional>,
<replaceable>subexpr
</replaceable>
6141 </optional></optional></optional></optional>).
6142 <replaceable>pattern
</replaceable> is searched for
6143 in
<replaceable>string
</replaceable>, normally from the beginning of
6144 the string, but if the
<replaceable>start
</replaceable> parameter is
6145 provided then beginning from that character index.
6146 If
<replaceable>N
</replaceable> is specified
6147 then the
<replaceable>N
</replaceable>'th match of the pattern
6148 is returned, otherwise the first match is returned.
6149 The
<replaceable>flags
</replaceable> parameter is an optional text
6150 string containing zero or more single-letter flags that change the
6151 function's behavior. Supported flags are described
6152 in
<xref linkend=
"posix-embedded-options-table"/>.
6153 For a pattern containing parenthesized
6154 subexpressions,
<replaceable>subexpr
</replaceable> is an integer
6155 indicating which subexpression is of interest: the result is the
6156 substring matching that subexpression.
6157 Subexpressions are numbered in the order of their leading parentheses.
6158 When
<replaceable>subexpr
</replaceable> is omitted or zero, the result
6159 is the whole match regardless of parenthesized subexpressions.
6165 regexp_substr('number of your street, town zip, FR', '[^,]+',
1,
2)
6166 <lineannotation> town zip
</lineannotation>
6167 regexp_substr('ABCDEFGHI', '(c..)(...)',
1,
1, 'i',
2)
6168 <lineannotation>FGH
</lineannotation>
6172 <!-- derived from the re_syntax.n man page -->
6174 <sect3 id=
"posix-syntax-details">
6175 <title>Regular Expression Details
</title>
6178 <productname>PostgreSQL
</productname>'s regular expressions are implemented
6179 using a software package written by Henry Spencer. Much of
6180 the description of regular expressions below is copied verbatim from his
6185 Regular expressions (
<acronym>RE
</acronym>s), as defined in
6186 <acronym>POSIX
</acronym> 1003.2, come in two forms:
6187 <firstterm>extended
</firstterm> <acronym>RE
</acronym>s or
<acronym>ERE
</acronym>s
6188 (roughly those of
<command>egrep
</command>), and
6189 <firstterm>basic
</firstterm> <acronym>RE
</acronym>s or
<acronym>BRE
</acronym>s
6190 (roughly those of
<command>ed
</command>).
6191 <productname>PostgreSQL
</productname> supports both forms, and
6192 also implements some extensions
6193 that are not in the POSIX standard, but have become widely used
6194 due to their availability in programming languages such as Perl and Tcl.
6195 <acronym>RE
</acronym>s using these non-POSIX extensions are called
6196 <firstterm>advanced
</firstterm> <acronym>RE
</acronym>s or
<acronym>ARE
</acronym>s
6197 in this documentation. AREs are almost an exact superset of EREs,
6198 but BREs have several notational incompatibilities (as well as being
6200 We first describe the ARE and ERE forms, noting features that apply
6201 only to AREs, and then describe how BREs differ.
6206 <productname>PostgreSQL
</productname> always initially presumes that a regular
6207 expression follows the ARE rules. However, the more limited ERE or
6208 BRE rules can be chosen by prepending an
<firstterm>embedded option
</firstterm>
6209 to the RE pattern, as described in
<xref linkend=
"posix-metasyntax"/>.
6210 This can be useful for compatibility with applications that expect
6211 exactly the
<acronym>POSIX
</acronym> 1003.2 rules.
6216 A regular expression is defined as one or more
6217 <firstterm>branches
</firstterm>, separated by
6218 <literal>|
</literal>. It matches anything that matches one of the
6223 A branch is zero or more
<firstterm>quantified atoms
</firstterm> or
6224 <firstterm>constraints
</firstterm>, concatenated.
6225 It matches a match for the first, followed by a match for the second, etc.;
6226 an empty branch matches the empty string.
6230 A quantified atom is an
<firstterm>atom
</firstterm> possibly followed
6231 by a single
<firstterm>quantifier
</firstterm>.
6232 Without a quantifier, it matches a match for the atom.
6233 With a quantifier, it can match some number of matches of the atom.
6234 An
<firstterm>atom
</firstterm> can be any of the possibilities
6235 shown in
<xref linkend=
"posix-atoms-table"/>.
6236 The possible quantifiers and their meanings are shown in
6237 <xref linkend=
"posix-quantifiers-table"/>.
6241 A
<firstterm>constraint
</firstterm> matches an empty string, but matches only when
6242 specific conditions are met. A constraint can be used where an atom
6243 could be used, except it cannot be followed by a quantifier.
6244 The simple constraints are shown in
6245 <xref linkend=
"posix-constraints-table"/>;
6246 some more constraints are described later.
6250 <table id=
"posix-atoms-table">
6251 <title>Regular Expression Atoms
</title>
6257 <entry>Description
</entry>
6263 <entry> <literal>(
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6264 <entry> (where
<replaceable>re
</replaceable> is any regular expression)
6266 <replaceable>re
</replaceable>, with the match noted for possible reporting
</entry>
6270 <entry> <literal>(?:
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6271 <entry> as above, but the match is not noted for reporting
6272 (a
<quote>non-capturing
</quote> set of parentheses)
6273 (AREs only)
</entry>
6277 <entry> <literal>.
</literal> </entry>
6278 <entry> matches any single character
</entry>
6282 <entry> <literal>[
</literal><replaceable>chars
</replaceable><literal>]
</literal> </entry>
6283 <entry> a
<firstterm>bracket expression
</firstterm>,
6284 matching any one of the
<replaceable>chars
</replaceable> (see
6285 <xref linkend=
"posix-bracket-expressions"/> for more detail)
</entry>
6289 <entry> <literal>\
</literal><replaceable>k
</replaceable> </entry>
6290 <entry> (where
<replaceable>k
</replaceable> is a non-alphanumeric character)
6291 matches that character taken as an ordinary character,
6292 e.g.,
<literal>\\
</literal> matches a backslash character
</entry>
6296 <entry> <literal>\
</literal><replaceable>c
</replaceable> </entry>
6297 <entry> where
<replaceable>c
</replaceable> is alphanumeric
6298 (possibly followed by other characters)
6299 is an
<firstterm>escape
</firstterm>, see
<xref linkend=
"posix-escape-sequences"/>
6300 (AREs only; in EREs and BREs, this matches
<replaceable>c
</replaceable>)
</entry>
6304 <entry> <literal>{
</literal> </entry>
6305 <entry> when followed by a character other than a digit,
6306 matches the left-brace character
<literal>{
</literal>;
6307 when followed by a digit, it is the beginning of a
6308 <replaceable>bound
</replaceable> (see below)
</entry>
6312 <entry> <replaceable>x
</replaceable> </entry>
6313 <entry> where
<replaceable>x
</replaceable> is a single character with no other
6314 significance, matches that character
</entry>
6321 An RE cannot end with a backslash (
<literal>\
</literal>).
6326 If you have
<xref linkend=
"guc-standard-conforming-strings"/> turned off,
6327 any backslashes you write in literal string constants will need to be
6328 doubled. See
<xref linkend=
"sql-syntax-strings"/> for more information.
6332 <table id=
"posix-quantifiers-table">
6333 <title>Regular Expression Quantifiers
</title>
6338 <entry>Quantifier
</entry>
6339 <entry>Matches
</entry>
6345 <entry> <literal>*
</literal> </entry>
6346 <entry> a sequence of
0 or more matches of the atom
</entry>
6350 <entry> <literal>+
</literal> </entry>
6351 <entry> a sequence of
1 or more matches of the atom
</entry>
6355 <entry> <literal>?
</literal> </entry>
6356 <entry> a sequence of
0 or
1 matches of the atom
</entry>
6360 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal> </entry>
6361 <entry> a sequence of exactly
<replaceable>m
</replaceable> matches of the atom
</entry>
6365 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>,}
</literal> </entry>
6366 <entry> a sequence of
<replaceable>m
</replaceable> or more matches of the atom
</entry>
6371 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal> </entry>
6372 <entry> a sequence of
<replaceable>m
</replaceable> through
<replaceable>n
</replaceable>
6373 (inclusive) matches of the atom;
<replaceable>m
</replaceable> cannot exceed
6374 <replaceable>n
</replaceable> </entry>
6378 <entry> <literal>*?
</literal> </entry>
6379 <entry> non-greedy version of
<literal>*
</literal> </entry>
6383 <entry> <literal>+?
</literal> </entry>
6384 <entry> non-greedy version of
<literal>+
</literal> </entry>
6388 <entry> <literal>??
</literal> </entry>
6389 <entry> non-greedy version of
<literal>?
</literal> </entry>
6393 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>}?
</literal> </entry>
6394 <entry> non-greedy version of
<literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal> </entry>
6398 <entry> <literal>{
</literal><replaceable>m
</replaceable><literal>,}?
</literal> </entry>
6399 <entry> non-greedy version of
<literal>{
</literal><replaceable>m
</replaceable><literal>,}
</literal> </entry>
6404 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}?
</literal> </entry>
6405 <entry> non-greedy version of
<literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal> </entry>
6412 The forms using
<literal>{
</literal><replaceable>...
</replaceable><literal>}
</literal>
6413 are known as
<firstterm>bounds
</firstterm>.
6414 The numbers
<replaceable>m
</replaceable> and
<replaceable>n
</replaceable> within a bound are
6415 unsigned decimal integers with permissible values from
0 to
255 inclusive.
6419 <firstterm>Non-greedy
</firstterm> quantifiers (available in AREs only) match the
6420 same possibilities as their corresponding normal (
<firstterm>greedy
</firstterm>)
6421 counterparts, but prefer the smallest number rather than the largest
6423 See
<xref linkend=
"posix-matching-rules"/> for more detail.
6428 A quantifier cannot immediately follow another quantifier, e.g.,
6429 <literal>**
</literal> is invalid.
6431 begin an expression or subexpression or follow
6432 <literal>^
</literal> or
<literal>|
</literal>.
6436 <table id=
"posix-constraints-table">
6437 <title>Regular Expression Constraints
</title>
6442 <entry>Constraint
</entry>
6443 <entry>Description
</entry>
6449 <entry> <literal>^
</literal> </entry>
6450 <entry> matches at the beginning of the string
</entry>
6454 <entry> <literal>$
</literal> </entry>
6455 <entry> matches at the end of the string
</entry>
6459 <entry> <literal>(?=
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6460 <entry> <firstterm>positive lookahead
</firstterm> matches at any point
6461 where a substring matching
<replaceable>re
</replaceable> begins
6462 (AREs only)
</entry>
6466 <entry> <literal>(?!
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6467 <entry> <firstterm>negative lookahead
</firstterm> matches at any point
6468 where no substring matching
<replaceable>re
</replaceable> begins
6469 (AREs only)
</entry>
6473 <entry> <literal>(?
<=
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6474 <entry> <firstterm>positive lookbehind
</firstterm> matches at any point
6475 where a substring matching
<replaceable>re
</replaceable> ends
6476 (AREs only)
</entry>
6480 <entry> <literal>(?
<!
</literal><replaceable>re
</replaceable><literal>)
</literal> </entry>
6481 <entry> <firstterm>negative lookbehind
</firstterm> matches at any point
6482 where no substring matching
<replaceable>re
</replaceable> ends
6483 (AREs only)
</entry>
6490 Lookahead and lookbehind constraints cannot contain
<firstterm>back
6491 references
</firstterm> (see
<xref linkend=
"posix-escape-sequences"/>),
6492 and all parentheses within them are considered non-capturing.
6496 <sect3 id=
"posix-bracket-expressions">
6497 <title>Bracket Expressions
</title>
6500 A
<firstterm>bracket expression
</firstterm> is a list of
6501 characters enclosed in
<literal>[]
</literal>. It normally matches
6502 any single character from the list (but see below). If the list
6503 begins with
<literal>^
</literal>, it matches any single character
6504 <emphasis>not
</emphasis> from the rest of the list.
6506 in the list are separated by
<literal>-
</literal>, this is
6507 shorthand for the full range of characters between those two
6508 (inclusive) in the collating sequence,
6509 e.g.,
<literal>[
0-
9]
</literal> in
<acronym>ASCII
</acronym> matches
6510 any decimal digit. It is illegal for two ranges to share an
6511 endpoint, e.g.,
<literal>a-c-e
</literal>. Ranges are very
6512 collating-sequence-dependent, so portable programs should avoid
6517 To include a literal
<literal>]
</literal> in the list, make it the
6518 first character (after
<literal>^
</literal>, if that is used). To
6519 include a literal
<literal>-
</literal>, make it the first or last
6520 character, or the second endpoint of a range. To use a literal
6521 <literal>-
</literal> as the first endpoint of a range, enclose it
6522 in
<literal>[.
</literal> and
<literal>.]
</literal> to make it a
6523 collating element (see below). With the exception of these characters,
6524 some combinations using
<literal>[
</literal>
6525 (see next paragraphs), and escapes (AREs only), all other special
6526 characters lose their special significance within a bracket expression.
6527 In particular,
<literal>\
</literal> is not special when following
6528 ERE or BRE rules, though it is special (as introducing an escape)
6533 Within a bracket expression, a collating element (a character, a
6534 multiple-character sequence that collates as if it were a single
6535 character, or a collating-sequence name for either) enclosed in
6536 <literal>[.
</literal> and
<literal>.]
</literal> stands for the
6537 sequence of characters of that collating element. The sequence is
6538 treated as a single element of the bracket expression's list. This
6540 expression containing a multiple-character collating element to
6541 match more than one character, e.g., if the collating sequence
6542 includes a
<literal>ch
</literal> collating element, then the RE
6543 <literal>[[.ch.]]*c
</literal> matches the first five characters of
6544 <literal>chchcc
</literal>.
6549 <productname>PostgreSQL
</productname> currently does not support multi-character collating
6550 elements. This information describes possible future behavior.
6555 Within a bracket expression, a collating element enclosed in
6556 <literal>[=
</literal> and
<literal>=]
</literal> is an
<firstterm>equivalence
6557 class
</firstterm>, standing for the sequences of characters of all collating
6558 elements equivalent to that one, including itself. (If there are
6559 no other equivalent collating elements, the treatment is as if the
6560 enclosing delimiters were
<literal>[.
</literal> and
6561 <literal>.]
</literal>.) For example, if
<literal>o
</literal> and
6562 <literal>^
</literal> are the members of an equivalence class, then
6563 <literal>[[=o=]]
</literal>,
<literal>[[=^=]]
</literal>, and
6564 <literal>[o^]
</literal> are all synonymous. An equivalence class
6565 cannot be an endpoint of a range.
6569 Within a bracket expression, the name of a character class
6570 enclosed in
<literal>[:
</literal> and
<literal>:]
</literal> stands
6571 for the list of all characters belonging to that class. A character
6572 class cannot be used as an endpoint of a range.
6573 The
<acronym>POSIX
</acronym> standard defines these character class
6575 <literal>alnum
</literal> (letters and numeric digits),
6576 <literal>alpha
</literal> (letters),
6577 <literal>blank
</literal> (space and tab),
6578 <literal>cntrl
</literal> (control characters),
6579 <literal>digit
</literal> (numeric digits),
6580 <literal>graph
</literal> (printable characters except space),
6581 <literal>lower
</literal> (lower-case letters),
6582 <literal>print
</literal> (printable characters including space),
6583 <literal>punct
</literal> (punctuation),
6584 <literal>space
</literal> (any white space),
6585 <literal>upper
</literal> (upper-case letters),
6586 and
<literal>xdigit
</literal> (hexadecimal digits).
6587 The behavior of these standard character classes is generally
6588 consistent across platforms for characters in the
7-bit ASCII set.
6589 Whether a given non-ASCII character is considered to belong to one
6590 of these classes depends on the
<firstterm>collation
</firstterm>
6591 that is used for the regular-expression function or operator
6592 (see
<xref linkend=
"collation"/>), or by default on the
6593 database's
<envar>LC_CTYPE
</envar> locale setting (see
6594 <xref linkend=
"locale"/>). The classification of non-ASCII
6595 characters can vary across platforms even in similarly-named
6596 locales. (But the
<literal>C
</literal> locale never considers any
6597 non-ASCII characters to belong to any of these classes.)
6598 In addition to these standard character
6599 classes,
<productname>PostgreSQL
</productname> defines
6600 the
<literal>word
</literal> character class, which is the same as
6601 <literal>alnum
</literal> plus the underscore (
<literal>_
</literal>)
6603 the
<literal>ascii
</literal> character class, which contains exactly
6604 the
7-bit ASCII set.
6608 There are two special cases of bracket expressions: the bracket
6609 expressions
<literal>[[:
<:]]
</literal> and
6610 <literal>[[:
>:]]
</literal> are constraints,
6611 matching empty strings at the beginning
6612 and end of a word respectively. A word is defined as a sequence
6613 of word characters that is neither preceded nor followed by word
6614 characters. A word character is any character belonging to the
6615 <literal>word
</literal> character class, that is, any letter, digit,
6616 or underscore. This is an extension, compatible with but not
6617 specified by
<acronym>POSIX
</acronym> 1003.2, and should be used with
6618 caution in software intended to be portable to other systems.
6619 The constraint escapes described below are usually preferable; they
6620 are no more standard, but are easier to type.
6624 <sect3 id=
"posix-escape-sequences">
6625 <title>Regular Expression Escapes
</title>
6628 <firstterm>Escapes
</firstterm> are special sequences beginning with
<literal>\
</literal>
6629 followed by an alphanumeric character. Escapes come in several varieties:
6630 character entry, class shorthands, constraint escapes, and back references.
6631 A
<literal>\
</literal> followed by an alphanumeric character but not constituting
6632 a valid escape is illegal in AREs.
6633 In EREs, there are no escapes: outside a bracket expression,
6634 a
<literal>\
</literal> followed by an alphanumeric character merely stands for
6635 that character as an ordinary character, and inside a bracket expression,
6636 <literal>\
</literal> is an ordinary character.
6637 (The latter is the one actual incompatibility between EREs and AREs.)
6641 <firstterm>Character-entry escapes
</firstterm> exist to make it easier to specify
6642 non-printing and other inconvenient characters in REs. They are
6643 shown in
<xref linkend=
"posix-character-entry-escapes-table"/>.
6647 <firstterm>Class-shorthand escapes
</firstterm> provide shorthands for certain
6648 commonly-used character classes. They are
6649 shown in
<xref linkend=
"posix-class-shorthand-escapes-table"/>.
6653 A
<firstterm>constraint escape
</firstterm> is a constraint,
6654 matching the empty string if specific conditions are met,
6655 written as an escape. They are
6656 shown in
<xref linkend=
"posix-constraint-escapes-table"/>.
6660 A
<firstterm>back reference
</firstterm> (
<literal>\
</literal><replaceable>n
</replaceable>) matches the
6661 same string matched by the previous parenthesized subexpression specified
6662 by the number
<replaceable>n
</replaceable>
6663 (see
<xref linkend=
"posix-constraint-backref-table"/>). For example,
6664 <literal>([bc])\
1</literal> matches
<literal>bb
</literal> or
<literal>cc
</literal>
6665 but not
<literal>bc
</literal> or
<literal>cb
</literal>.
6666 The subexpression must entirely precede the back reference in the RE.
6667 Subexpressions are numbered in the order of their leading parentheses.
6668 Non-capturing parentheses do not define subexpressions.
6669 The back reference considers only the string characters matched by the
6670 referenced subexpression, not any constraints contained in it. For
6671 example,
<literal>(^\d)\
1</literal> will match
<literal>22</literal>.
6674 <table id=
"posix-character-entry-escapes-table">
6675 <title>Regular Expression Character-Entry Escapes
</title>
6680 <entry>Escape
</entry>
6681 <entry>Description
</entry>
6687 <entry> <literal>\a
</literal> </entry>
6688 <entry> alert (bell) character, as in C
</entry>
6692 <entry> <literal>\b
</literal> </entry>
6693 <entry> backspace, as in C
</entry>
6697 <entry> <literal>\B
</literal> </entry>
6698 <entry> synonym for backslash (
<literal>\
</literal>) to help reduce the need for backslash
6703 <entry> <literal>\c
</literal><replaceable>X
</replaceable> </entry>
6704 <entry> (where
<replaceable>X
</replaceable> is any character) the character whose
6705 low-order
5 bits are the same as those of
6706 <replaceable>X
</replaceable>, and whose other bits are all zero
</entry>
6710 <entry> <literal>\e
</literal> </entry>
6711 <entry> the character whose collating-sequence name
6712 is
<literal>ESC
</literal>,
6713 or failing that, the character with octal value
<literal>033</literal> </entry>
6717 <entry> <literal>\f
</literal> </entry>
6718 <entry> form feed, as in C
</entry>
6722 <entry> <literal>\n
</literal> </entry>
6723 <entry> newline, as in C
</entry>
6727 <entry> <literal>\r
</literal> </entry>
6728 <entry> carriage return, as in C
</entry>
6732 <entry> <literal>\t
</literal> </entry>
6733 <entry> horizontal tab, as in C
</entry>
6737 <entry> <literal>\u
</literal><replaceable>wxyz
</replaceable> </entry>
6738 <entry> (where
<replaceable>wxyz
</replaceable> is exactly four hexadecimal digits)
6739 the character whose hexadecimal value is
6740 <literal>0x
</literal><replaceable>wxyz
</replaceable>
6745 <entry> <literal>\U
</literal><replaceable>stuvwxyz
</replaceable> </entry>
6746 <entry> (where
<replaceable>stuvwxyz
</replaceable> is exactly eight hexadecimal
6748 the character whose hexadecimal value is
6749 <literal>0x
</literal><replaceable>stuvwxyz
</replaceable>
6754 <entry> <literal>\v
</literal> </entry>
6755 <entry> vertical tab, as in C
</entry>
6759 <entry> <literal>\x
</literal><replaceable>hhh
</replaceable> </entry>
6760 <entry> (where
<replaceable>hhh
</replaceable> is any sequence of hexadecimal
6762 the character whose hexadecimal value is
6763 <literal>0x
</literal><replaceable>hhh
</replaceable>
6764 (a single character no matter how many hexadecimal digits are used)
6769 <entry> <literal>\
0</literal> </entry>
6770 <entry> the character whose value is
<literal>0</literal> (the null byte)
</entry>
6774 <entry> <literal>\
</literal><replaceable>xy
</replaceable> </entry>
6775 <entry> (where
<replaceable>xy
</replaceable> is exactly two octal digits,
6776 and is not a
<firstterm>back reference
</firstterm>)
6777 the character whose octal value is
6778 <literal>0</literal><replaceable>xy
</replaceable> </entry>
6782 <entry> <literal>\
</literal><replaceable>xyz
</replaceable> </entry>
6783 <entry> (where
<replaceable>xyz
</replaceable> is exactly three octal digits,
6784 and is not a
<firstterm>back reference
</firstterm>)
6785 the character whose octal value is
6786 <literal>0</literal><replaceable>xyz
</replaceable> </entry>
6793 Hexadecimal digits are
<literal>0</literal>-
<literal>9</literal>,
6794 <literal>a
</literal>-
<literal>f
</literal>, and
<literal>A
</literal>-
<literal>F
</literal>.
6795 Octal digits are
<literal>0</literal>-
<literal>7</literal>.
6799 Numeric character-entry escapes specifying values outside the ASCII range
6800 (
0–127) have meanings dependent on the database encoding. When the
6801 encoding is UTF-
8, escape values are equivalent to Unicode code points,
6802 for example
<literal>\u1234
</literal> means the character
<literal>U+
1234</literal>.
6803 For other multibyte encodings, character-entry escapes usually just
6804 specify the concatenation of the byte values for the character. If the
6805 escape value does not correspond to any legal character in the database
6806 encoding, no error will be raised, but it will never match any data.
6810 The character-entry escapes are always taken as ordinary characters.
6811 For example,
<literal>\
135</literal> is
<literal>]
</literal> in ASCII, but
6812 <literal>\
135</literal> does not terminate a bracket expression.
6815 <table id=
"posix-class-shorthand-escapes-table">
6816 <title>Regular Expression Class-Shorthand Escapes
</title>
6821 <entry>Escape
</entry>
6822 <entry>Description
</entry>
6828 <entry> <literal>\d
</literal> </entry>
6829 <entry> matches any digit, like
6830 <literal>[[:digit:]]
</literal> </entry>
6834 <entry> <literal>\s
</literal> </entry>
6835 <entry> matches any whitespace character, like
6836 <literal>[[:space:]]
</literal> </entry>
6840 <entry> <literal>\w
</literal> </entry>
6841 <entry> matches any word character, like
6842 <literal>[[:word:]]
</literal> </entry>
6846 <entry> <literal>\D
</literal> </entry>
6847 <entry> matches any non-digit, like
6848 <literal>[^[:digit:]]
</literal> </entry>
6852 <entry> <literal>\S
</literal> </entry>
6853 <entry> matches any non-whitespace character, like
6854 <literal>[^[:space:]]
</literal> </entry>
6858 <entry> <literal>\W
</literal> </entry>
6859 <entry> matches any non-word character, like
6860 <literal>[^[:word:]]
</literal> </entry>
6867 The class-shorthand escapes also work within bracket expressions,
6868 although the definitions shown above are not quite syntactically
6869 valid in that context.
6870 For example,
<literal>[a-c\d]
</literal> is equivalent to
6871 <literal>[a-c[:digit:]]
</literal>.
6874 <table id=
"posix-constraint-escapes-table">
6875 <title>Regular Expression Constraint Escapes
</title>
6880 <entry>Escape
</entry>
6881 <entry>Description
</entry>
6887 <entry> <literal>\A
</literal> </entry>
6888 <entry> matches only at the beginning of the string
6889 (see
<xref linkend=
"posix-matching-rules"/> for how this differs from
6890 <literal>^
</literal>)
</entry>
6894 <entry> <literal>\m
</literal> </entry>
6895 <entry> matches only at the beginning of a word
</entry>
6899 <entry> <literal>\M
</literal> </entry>
6900 <entry> matches only at the end of a word
</entry>
6904 <entry> <literal>\y
</literal> </entry>
6905 <entry> matches only at the beginning or end of a word
</entry>
6909 <entry> <literal>\Y
</literal> </entry>
6910 <entry> matches only at a point that is not the beginning or end of a
6915 <entry> <literal>\Z
</literal> </entry>
6916 <entry> matches only at the end of the string
6917 (see
<xref linkend=
"posix-matching-rules"/> for how this differs from
6918 <literal>$
</literal>)
</entry>
6925 A word is defined as in the specification of
6926 <literal>[[:
<:]]
</literal> and
<literal>[[:
>:]]
</literal> above.
6927 Constraint escapes are illegal within bracket expressions.
6930 <table id=
"posix-constraint-backref-table">
6931 <title>Regular Expression Back References
</title>
6936 <entry>Escape
</entry>
6937 <entry>Description
</entry>
6943 <entry> <literal>\
</literal><replaceable>m
</replaceable> </entry>
6944 <entry> (where
<replaceable>m
</replaceable> is a nonzero digit)
6945 a back reference to the
<replaceable>m
</replaceable>'th subexpression
</entry>
6949 <entry> <literal>\
</literal><replaceable>mnn
</replaceable> </entry>
6950 <entry> (where
<replaceable>m
</replaceable> is a nonzero digit, and
6951 <replaceable>nn
</replaceable> is some more digits, and the decimal value
6952 <replaceable>mnn
</replaceable> is not greater than the number of closing capturing
6953 parentheses seen so far)
6954 a back reference to the
<replaceable>mnn
</replaceable>'th subexpression
</entry>
6962 There is an inherent ambiguity between octal character-entry
6963 escapes and back references, which is resolved by the following heuristics,
6965 A leading zero always indicates an octal escape.
6966 A single non-zero digit, not followed by another digit,
6967 is always taken as a back reference.
6968 A multi-digit sequence not starting with a zero is taken as a back
6969 reference if it comes after a suitable subexpression
6970 (i.e., the number is in the legal range for a back reference),
6971 and otherwise is taken as octal.
6976 <sect3 id=
"posix-metasyntax">
6977 <title>Regular Expression Metasyntax
</title>
6980 In addition to the main syntax described above, there are some special
6981 forms and miscellaneous syntactic facilities available.
6985 An RE can begin with one of two special
<firstterm>director
</firstterm> prefixes.
6986 If an RE begins with
<literal>***:
</literal>,
6987 the rest of the RE is taken as an ARE. (This normally has no effect in
6988 <productname>PostgreSQL
</productname>, since REs are assumed to be AREs;
6989 but it does have an effect if ERE or BRE mode had been specified by
6990 the
<replaceable>flags
</replaceable> parameter to a regex function.)
6991 If an RE begins with
<literal>***=
</literal>,
6992 the rest of the RE is taken to be a literal string,
6993 with all characters considered ordinary characters.
6997 An ARE can begin with
<firstterm>embedded options
</firstterm>:
6998 a sequence
<literal>(?
</literal><replaceable>xyz
</replaceable><literal>)
</literal>
6999 (where
<replaceable>xyz
</replaceable> is one or more alphabetic characters)
7000 specifies options affecting the rest of the RE.
7001 These options override any previously determined options
—
7002 in particular, they can override the case-sensitivity behavior implied by
7003 a regex operator, or the
<replaceable>flags
</replaceable> parameter to a regex
7005 The available option letters are
7006 shown in
<xref linkend=
"posix-embedded-options-table"/>.
7007 Note that these same option letters are used in the
<replaceable>flags
</replaceable>
7008 parameters of regex functions.
7011 <table id=
"posix-embedded-options-table">
7012 <title>ARE Embedded-Option Letters
</title>
7017 <entry>Option
</entry>
7018 <entry>Description
</entry>
7024 <entry> <literal>b
</literal> </entry>
7025 <entry> rest of RE is a BRE
</entry>
7029 <entry> <literal>c
</literal> </entry>
7030 <entry> case-sensitive matching (overrides operator type)
</entry>
7034 <entry> <literal>e
</literal> </entry>
7035 <entry> rest of RE is an ERE
</entry>
7039 <entry> <literal>i
</literal> </entry>
7040 <entry> case-insensitive matching (see
7041 <xref linkend=
"posix-matching-rules"/>) (overrides operator type)
</entry>
7045 <entry> <literal>m
</literal> </entry>
7046 <entry> historical synonym for
<literal>n
</literal> </entry>
7050 <entry> <literal>n
</literal> </entry>
7051 <entry> newline-sensitive matching (see
7052 <xref linkend=
"posix-matching-rules"/>)
</entry>
7056 <entry> <literal>p
</literal> </entry>
7057 <entry> partial newline-sensitive matching (see
7058 <xref linkend=
"posix-matching-rules"/>)
</entry>
7062 <entry> <literal>q
</literal> </entry>
7063 <entry> rest of RE is a literal (
<quote>quoted
</quote>) string, all ordinary
7068 <entry> <literal>s
</literal> </entry>
7069 <entry> non-newline-sensitive matching (default)
</entry>
7073 <entry> <literal>t
</literal> </entry>
7074 <entry> tight syntax (default; see below)
</entry>
7078 <entry> <literal>w
</literal> </entry>
7079 <entry> inverse partial newline-sensitive (
<quote>weird
</quote>) matching
7080 (see
<xref linkend=
"posix-matching-rules"/>)
</entry>
7084 <entry> <literal>x
</literal> </entry>
7085 <entry> expanded syntax (see below)
</entry>
7092 Embedded options take effect at the
<literal>)
</literal> terminating the sequence.
7093 They can appear only at the start of an ARE (after the
7094 <literal>***:
</literal> director if any).
7098 In addition to the usual (
<firstterm>tight
</firstterm>) RE syntax, in which all
7099 characters are significant, there is an
<firstterm>expanded
</firstterm> syntax,
7100 available by specifying the embedded
<literal>x
</literal> option.
7101 In the expanded syntax,
7102 white-space characters in the RE are ignored, as are
7103 all characters between a
<literal>#
</literal>
7104 and the following newline (or the end of the RE). This
7105 permits paragraphing and commenting a complex RE.
7106 There are three exceptions to that basic rule:
7111 a white-space character or
<literal>#
</literal> preceded by
<literal>\
</literal> is
7117 white space or
<literal>#
</literal> within a bracket expression is retained
7122 white space and comments cannot appear within multi-character symbols,
7123 such as
<literal>(?:
</literal>
7128 For this purpose, white-space characters are blank, tab, newline, and
7129 any character that belongs to the
<replaceable>space
</replaceable> character class.
7133 Finally, in an ARE, outside bracket expressions, the sequence
7134 <literal>(?#
</literal><replaceable>ttt
</replaceable><literal>)
</literal>
7135 (where
<replaceable>ttt
</replaceable> is any text not containing a
<literal>)
</literal>)
7136 is a comment, completely ignored.
7137 Again, this is not allowed between the characters of
7138 multi-character symbols, like
<literal>(?:
</literal>.
7139 Such comments are more a historical artifact than a useful facility,
7140 and their use is deprecated; use the expanded syntax instead.
7144 <emphasis>None
</emphasis> of these metasyntax extensions is available if
7145 an initial
<literal>***=
</literal> director
7146 has specified that the user's input be treated as a literal string
7147 rather than as an RE.
7151 <sect3 id=
"posix-matching-rules">
7152 <title>Regular Expression Matching Rules
</title>
7155 In the event that an RE could match more than one substring of a given
7156 string, the RE matches the one starting earliest in the string.
7157 If the RE could match more than one substring starting at that point,
7158 either the longest possible match or the shortest possible match will
7159 be taken, depending on whether the RE is
<firstterm>greedy
</firstterm> or
7160 <firstterm>non-greedy
</firstterm>.
7164 Whether an RE is greedy or not is determined by the following rules:
7168 Most atoms, and all constraints, have no greediness attribute (because
7169 they cannot match variable amounts of text anyway).
7174 Adding parentheses around an RE does not change its greediness.
7179 A quantified atom with a fixed-repetition quantifier
7180 (
<literal>{
</literal><replaceable>m
</replaceable><literal>}
</literal>
7182 <literal>{
</literal><replaceable>m
</replaceable><literal>}?
</literal>)
7183 has the same greediness (possibly none) as the atom itself.
7188 A quantified atom with other normal quantifiers (including
7189 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}
</literal>
7190 with
<replaceable>m
</replaceable> equal to
<replaceable>n
</replaceable>)
7191 is greedy (prefers longest match).
7196 A quantified atom with a non-greedy quantifier (including
7197 <literal>{
</literal><replaceable>m
</replaceable><literal>,
</literal><replaceable>n
</replaceable><literal>}?
</literal>
7198 with
<replaceable>m
</replaceable> equal to
<replaceable>n
</replaceable>)
7199 is non-greedy (prefers shortest match).
7204 A branch
— that is, an RE that has no top-level
7205 <literal>|
</literal> operator
— has the same greediness as the first
7206 quantified atom in it that has a greediness attribute.
7211 An RE consisting of two or more branches connected by the
7212 <literal>|
</literal> operator is always greedy.
7219 The above rules associate greediness attributes not only with individual
7220 quantified atoms, but with branches and entire REs that contain quantified
7221 atoms. What that means is that the matching is done in such a way that
7222 the branch, or whole RE, matches the longest or shortest possible
7223 substring
<emphasis>as a whole
</emphasis>. Once the length of the entire match
7224 is determined, the part of it that matches any particular subexpression
7225 is determined on the basis of the greediness attribute of that
7226 subexpression, with subexpressions starting earlier in the RE taking
7227 priority over ones starting later.
7231 An example of what this means:
7233 SELECT SUBSTRING('XY1234Z', 'Y*([
0-
9]{
1,
3})');
7234 <lineannotation>Result:
</lineannotation><computeroutput>123</computeroutput>
7235 SELECT SUBSTRING('XY1234Z', 'Y*?([
0-
9]{
1,
3})');
7236 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
7238 In the first case, the RE as a whole is greedy because
<literal>Y*
</literal>
7239 is greedy. It can match beginning at the
<literal>Y
</literal>, and it matches
7240 the longest possible string starting there, i.e.,
<literal>Y123
</literal>.
7241 The output is the parenthesized part of that, or
<literal>123</literal>.
7242 In the second case, the RE as a whole is non-greedy because
<literal>Y*?
</literal>
7243 is non-greedy. It can match beginning at the
<literal>Y
</literal>, and it matches
7244 the shortest possible string starting there, i.e.,
<literal>Y1
</literal>.
7245 The subexpression
<literal>[
0-
9]{
1,
3}
</literal> is greedy but it cannot change
7246 the decision as to the overall match length; so it is forced to match
7247 just
<literal>1</literal>.
7251 In short, when an RE contains both greedy and non-greedy subexpressions,
7252 the total match length is either as long as possible or as short as
7253 possible, according to the attribute assigned to the whole RE. The
7254 attributes assigned to the subexpressions only affect how much of that
7255 match they are allowed to
<quote>eat
</quote> relative to each other.
7259 The quantifiers
<literal>{
1,
1}
</literal> and
<literal>{
1,
1}?
</literal>
7260 can be used to force greediness or non-greediness, respectively,
7261 on a subexpression or a whole RE.
7262 This is useful when you need the whole RE to have a greediness attribute
7263 different from what's deduced from its elements. As an example,
7264 suppose that we are trying to separate a string containing some digits
7265 into the digits and the parts before and after them. We might try to
7268 SELECT regexp_match('abc01234xyz', '(.*)(\d+)(.*)');
7269 <lineannotation>Result:
</lineannotation><computeroutput>{abc0123,
4,xyz}
</computeroutput>
7271 That didn't work: the first
<literal>.*
</literal> is greedy so
7272 it
<quote>eats
</quote> as much as it can, leaving the
<literal>\d+
</literal> to
7273 match at the last possible place, the last digit. We might try to fix
7274 that by making it non-greedy:
7276 SELECT regexp_match('abc01234xyz', '(.*?)(\d+)(.*)');
7277 <lineannotation>Result:
</lineannotation><computeroutput>{abc,
0,
""}
</computeroutput>
7279 That didn't work either, because now the RE as a whole is non-greedy
7280 and so it ends the overall match as soon as possible. We can get what
7281 we want by forcing the RE as a whole to be greedy:
7283 SELECT regexp_match('abc01234xyz', '(?:(.*?)(\d+)(.*)){
1,
1}');
7284 <lineannotation>Result:
</lineannotation><computeroutput>{abc,
01234,xyz}
</computeroutput>
7286 Controlling the RE's overall greediness separately from its components'
7287 greediness allows great flexibility in handling variable-length patterns.
7291 When deciding what is a longer or shorter match,
7292 match lengths are measured in characters, not collating elements.
7293 An empty string is considered longer than no match at all.
7295 <literal>bb*
</literal>
7296 matches the three middle characters of
<literal>abbbc
</literal>;
7297 <literal>(week|wee)(night|knights)
</literal>
7298 matches all ten characters of
<literal>weeknights
</literal>;
7299 when
<literal>(.*).*
</literal>
7300 is matched against
<literal>abc
</literal> the parenthesized subexpression
7301 matches all three characters; and when
7302 <literal>(a*)*
</literal> is matched against
<literal>bc
</literal>
7303 both the whole RE and the parenthesized
7304 subexpression match an empty string.
7308 If case-independent matching is specified,
7309 the effect is much as if all case distinctions had vanished from the
7311 When an alphabetic that exists in multiple cases appears as an
7312 ordinary character outside a bracket expression, it is effectively
7313 transformed into a bracket expression containing both cases,
7314 e.g.,
<literal>x
</literal> becomes
<literal>[xX]
</literal>.
7315 When it appears inside a bracket expression, all case counterparts
7316 of it are added to the bracket expression, e.g.,
7317 <literal>[x]
</literal> becomes
<literal>[xX]
</literal>
7318 and
<literal>[^x]
</literal> becomes
<literal>[^xX]
</literal>.
7322 If newline-sensitive matching is specified,
<literal>.
</literal>
7323 and bracket expressions using
<literal>^
</literal>
7324 will never match the newline character
7325 (so that matches will not cross lines unless the RE
7326 explicitly includes a newline)
7327 and
<literal>^
</literal> and
<literal>$
</literal>
7328 will match the empty string after and before a newline
7329 respectively, in addition to matching at beginning and end of string
7331 But the ARE escapes
<literal>\A
</literal> and
<literal>\Z
</literal>
7332 continue to match beginning or end of string
<emphasis>only
</emphasis>.
7333 Also, the character class shorthands
<literal>\D
</literal>
7334 and
<literal>\W
</literal> will match a newline regardless of this mode.
7335 (Before
<productname>PostgreSQL
</productname> 14, they did not match
7336 newlines when in newline-sensitive mode.
7337 Write
<literal>[^[:digit:]]
</literal>
7338 or
<literal>[^[:word:]]
</literal> to get the old behavior.)
7342 If partial newline-sensitive matching is specified,
7343 this affects
<literal>.
</literal> and bracket expressions
7344 as with newline-sensitive matching, but not
<literal>^
</literal>
7345 and
<literal>$
</literal>.
7349 If inverse partial newline-sensitive matching is specified,
7350 this affects
<literal>^
</literal> and
<literal>$
</literal>
7351 as with newline-sensitive matching, but not
<literal>.
</literal>
7352 and bracket expressions.
7353 This isn't very useful but is provided for symmetry.
7357 <sect3 id=
"posix-limits-compatibility">
7358 <title>Limits and Compatibility
</title>
7361 No particular limit is imposed on the length of REs in this
7362 implementation. However,
7363 programs intended to be highly portable should not employ REs longer
7365 as a POSIX-compliant implementation can refuse to accept such REs.
7369 The only feature of AREs that is actually incompatible with
7370 POSIX EREs is that
<literal>\
</literal> does not lose its special
7371 significance inside bracket expressions.
7372 All other ARE features use syntax which is illegal or has
7373 undefined or unspecified effects in POSIX EREs;
7374 the
<literal>***
</literal> syntax of directors likewise is outside the POSIX
7375 syntax for both BREs and EREs.
7379 Many of the ARE extensions are borrowed from Perl, but some have
7380 been changed to clean them up, and a few Perl extensions are not present.
7381 Incompatibilities of note include
<literal>\b
</literal>,
<literal>\B
</literal>,
7382 the lack of special treatment for a trailing newline,
7383 the addition of complemented bracket expressions to the things
7384 affected by newline-sensitive matching,
7385 the restrictions on parentheses and back references in lookahead/lookbehind
7386 constraints, and the longest/shortest-match (rather than first-match)
7391 <sect3 id=
"posix-basic-regexes">
7392 <title>Basic Regular Expressions
</title>
7395 BREs differ from EREs in several respects.
7396 In BREs,
<literal>|
</literal>,
<literal>+
</literal>, and
<literal>?
</literal>
7397 are ordinary characters and there is no equivalent
7398 for their functionality.
7399 The delimiters for bounds are
7400 <literal>\{
</literal> and
<literal>\}
</literal>,
7401 with
<literal>{
</literal> and
<literal>}
</literal>
7402 by themselves ordinary characters.
7403 The parentheses for nested subexpressions are
7404 <literal>\(
</literal> and
<literal>\)
</literal>,
7405 with
<literal>(
</literal> and
<literal>)
</literal> by themselves ordinary characters.
7406 <literal>^
</literal> is an ordinary character except at the beginning of the
7407 RE or the beginning of a parenthesized subexpression,
7408 <literal>$
</literal> is an ordinary character except at the end of the
7409 RE or the end of a parenthesized subexpression,
7410 and
<literal>*
</literal> is an ordinary character if it appears at the beginning
7411 of the RE or the beginning of a parenthesized subexpression
7412 (after a possible leading
<literal>^
</literal>).
7413 Finally, single-digit back references are available, and
7414 <literal>\
<</literal> and
<literal>\
></literal>
7416 <literal>[[:
<:]]
</literal> and
<literal>[[:
>:]]
</literal>
7417 respectively; no other escapes are available in BREs.
7421 <!-- end re_syntax.n man page -->
7423 <sect3 id=
"posix-vs-xquery">
7424 <title>Differences from SQL Standard and XQuery
</title>
7426 <indexterm zone=
"posix-vs-xquery">
7427 <primary>LIKE_REGEX
</primary>
7430 <indexterm zone=
"posix-vs-xquery">
7431 <primary>OCCURRENCES_REGEX
</primary>
7434 <indexterm zone=
"posix-vs-xquery">
7435 <primary>POSITION_REGEX
</primary>
7438 <indexterm zone=
"posix-vs-xquery">
7439 <primary>SUBSTRING_REGEX
</primary>
7442 <indexterm zone=
"posix-vs-xquery">
7443 <primary>TRANSLATE_REGEX
</primary>
7446 <indexterm zone=
"posix-vs-xquery">
7447 <primary>XQuery regular expressions
</primary>
7451 Since SQL:
2008, the SQL standard includes regular expression operators
7452 and functions that performs pattern
7453 matching according to the XQuery regular expression
7456 <listitem><para><literal>LIKE_REGEX
</literal></para></listitem>
7457 <listitem><para><literal>OCCURRENCES_REGEX
</literal></para></listitem>
7458 <listitem><para><literal>POSITION_REGEX
</literal></para></listitem>
7459 <listitem><para><literal>SUBSTRING_REGEX
</literal></para></listitem>
7460 <listitem><para><literal>TRANSLATE_REGEX
</literal></para></listitem>
7462 <productname>PostgreSQL
</productname> does not currently implement these
7463 operators and functions. You can get approximately equivalent
7464 functionality in each case as shown in
<xref
7465 linkend=
"functions-regexp-sql-table"/>. (Various optional clauses on
7466 both sides have been omitted in this table.)
7469 <table id=
"functions-regexp-sql-table">
7470 <title>Regular Expression Functions Equivalencies
</title>
7475 <entry>SQL standard
</entry>
7476 <entry><productname>PostgreSQL
</productname></entry>
7482 <entry><literal><replaceable>string
</replaceable> LIKE_REGEX
<replaceable>pattern
</replaceable></literal></entry>
7483 <entry><literal>regexp_like(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal> or
<literal><replaceable>string
</replaceable> ~
<replaceable>pattern
</replaceable></literal></entry>
7487 <entry><literal>OCCURRENCES_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable>)
</literal></entry>
7488 <entry><literal>regexp_count(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal></entry>
7492 <entry><literal>POSITION_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable>)
</literal></entry>
7493 <entry><literal>regexp_instr(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal></entry>
7497 <entry><literal>SUBSTRING_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable>)
</literal></entry>
7498 <entry><literal>regexp_substr(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>)
</literal></entry>
7502 <entry><literal>TRANSLATE_REGEX(
<replaceable>pattern
</replaceable> IN
<replaceable>string
</replaceable> WITH
<replaceable>replacement
</replaceable>)
</literal></entry>
7503 <entry><literal>regexp_replace(
<replaceable>string
</replaceable>,
<replaceable>pattern
</replaceable>,
<replaceable>replacement
</replaceable>)
</literal></entry>
7510 Regular expression functions similar to those provided by PostgreSQL are
7511 also available in a number of other SQL implementations, whereas the
7512 SQL-standard functions are not as widely implemented. Some of the
7513 details of the regular expression syntax will likely differ in each
7518 The SQL-standard operators and functions use XQuery regular expressions,
7519 which are quite close to the ARE syntax described above.
7520 Notable differences between the existing POSIX-based
7521 regular-expression feature and XQuery regular expressions include:
7526 XQuery character class subtraction is not supported. An example of
7527 this feature is using the following to match only English
7528 consonants:
<literal>[a-z-[aeiou]]
</literal>.
7533 XQuery character class shorthands
<literal>\c
</literal>,
7534 <literal>\C
</literal>,
<literal>\i
</literal>,
7535 and
<literal>\I
</literal> are not supported.
7540 XQuery character class elements
7541 using
<literal>\p{UnicodeProperty}
</literal> or the
7542 inverse
<literal>\P{UnicodeProperty}
</literal> are not supported.
7547 POSIX interprets character classes such as
<literal>\w
</literal>
7548 (see
<xref linkend=
"posix-class-shorthand-escapes-table"/>)
7549 according to the prevailing locale (which you can control by
7550 attaching a
<literal>COLLATE
</literal> clause to the operator or
7551 function). XQuery specifies these classes by reference to Unicode
7552 character properties, so equivalent behavior is obtained only with
7553 a locale that follows the Unicode rules.
7558 The SQL standard (not XQuery itself) attempts to cater for more
7559 variants of
<quote>newline
</quote> than POSIX does. The
7560 newline-sensitive matching options described above consider only
7561 ASCII NL (
<literal>\n
</literal>) to be a newline, but SQL would have
7562 us treat CR (
<literal>\r
</literal>), CRLF (
<literal>\r\n
</literal>)
7563 (a Windows-style newline), and some Unicode-only characters like
7564 LINE SEPARATOR (U+
2028) as newlines as well.
7565 Notably,
<literal>.
</literal> and
<literal>\s
</literal> should
7566 count
<literal>\r\n
</literal> as one character not two according to
7572 Of the character-entry escapes described in
7573 <xref linkend=
"posix-character-entry-escapes-table"/>,
7574 XQuery supports only
<literal>\n
</literal>,
<literal>\r
</literal>,
7575 and
<literal>\t
</literal>.
7580 XQuery does not support
7581 the
<literal>[:
<replaceable>name
</replaceable>:]
</literal> syntax
7582 for character classes within bracket expressions.
7587 XQuery does not have lookahead or lookbehind constraints,
7588 nor any of the constraint escapes described in
7589 <xref linkend=
"posix-constraint-escapes-table"/>.
7594 The metasyntax forms described in
<xref linkend=
"posix-metasyntax"/>
7595 do not exist in XQuery.
7600 The regular expression flag letters defined by XQuery are
7601 related to but not the same as the option letters for POSIX
7602 (
<xref linkend=
"posix-embedded-options-table"/>). While the
7603 <literal>i
</literal> and
<literal>q
</literal> options behave the
7604 same, others do not:
7608 XQuery's
<literal>s
</literal> (allow dot to match newline)
7609 and
<literal>m
</literal> (allow
<literal>^
</literal>
7610 and
<literal>$
</literal> to match at newlines) flags provide
7611 access to the same behaviors as
7612 POSIX's
<literal>n
</literal>,
<literal>p
</literal>
7613 and
<literal>w
</literal> flags, but they
7614 do
<emphasis>not
</emphasis> match the behavior of
7615 POSIX's
<literal>s
</literal> and
<literal>m
</literal> flags.
7616 Note in particular that dot-matches-newline is the default
7617 behavior in POSIX but not XQuery.
7622 XQuery's
<literal>x
</literal> (ignore whitespace in pattern) flag
7623 is noticeably different from POSIX's expanded-mode flag.
7624 POSIX's
<literal>x
</literal> flag also
7625 allows
<literal>#
</literal> to begin a comment in the pattern,
7626 and POSIX will not ignore a whitespace character after a
7641 <sect1 id=
"functions-formatting">
7642 <title>Data Type Formatting Functions
</title>
7645 <primary>formatting
</primary>
7649 The
<productname>PostgreSQL
</productname> formatting functions
7650 provide a powerful set of tools for converting various data types
7651 (date/time, integer, floating point, numeric) to formatted strings
7652 and for converting from formatted strings to specific data types.
7653 <xref linkend=
"functions-formatting-table"/> lists them.
7654 These functions all follow a common calling convention: the first
7655 argument is the value to be formatted and the second argument is a
7656 template that defines the output or input format.
7659 <table id=
"functions-formatting-table">
7660 <title>Formatting Functions
</title>
7664 <entry role=
"func_table_entry"><para role=
"func_signature">
7678 <entry role=
"func_table_entry"><para role=
"func_signature">
7680 <primary>to_char
</primary>
7682 <function>to_char
</function> (
<type>timestamp
</type>,
<type>text
</type> )
7683 <returnvalue>text
</returnvalue>
7685 <para role=
"func_signature">
7686 <function>to_char
</function> (
<type>timestamp with time zone
</type>,
<type>text
</type> )
7687 <returnvalue>text
</returnvalue>
7690 Converts time stamp to string according to the given format.
7693 <literal>to_char(timestamp '
2002-
04-
20 17:
31:
12.66', 'HH12:MI:SS')
</literal>
7694 <returnvalue>05:
31:
12</returnvalue>
7699 <entry role=
"func_table_entry"><para role=
"func_signature">
7700 <function>to_char
</function> (
<type>interval
</type>,
<type>text
</type> )
7701 <returnvalue>text
</returnvalue>
7704 Converts interval to string according to the given format.
7707 <literal>to_char(interval '
15h
2m
12s', 'HH24:MI:SS')
</literal>
7708 <returnvalue>15:
02:
12</returnvalue>
7713 <entry role=
"func_table_entry"><para role=
"func_signature">
7714 <function>to_char
</function> (
<replaceable>numeric_type
</replaceable>,
<type>text
</type> )
7715 <returnvalue>text
</returnvalue>
7718 Converts number to string according to the given format; available
7719 for
<type>integer
</type>,
<type>bigint
</type>,
<type>numeric
</type>,
7720 <type>real
</type>,
<type>double precision
</type>.
7723 <literal>to_char(
125, '
999')
</literal>
7724 <returnvalue>125</returnvalue>
7727 <literal>to_char(
125.8::real, '
999D9')
</literal>
7728 <returnvalue>125.8</returnvalue>
7731 <literal>to_char(-
125.8, '
999D99S')
</literal>
7732 <returnvalue>125.80-
</returnvalue>
7737 <entry role=
"func_table_entry"><para role=
"func_signature">
7739 <primary>to_date
</primary>
7741 <function>to_date
</function> (
<type>text
</type>,
<type>text
</type> )
7742 <returnvalue>date
</returnvalue>
7745 Converts string to date according to the given format.
7748 <literal>to_date('
05 Dec
2000', 'DD Mon YYYY')
</literal>
7749 <returnvalue>2000-
12-
05</returnvalue>
7754 <entry role=
"func_table_entry"><para role=
"func_signature">
7756 <primary>to_number
</primary>
7758 <function>to_number
</function> (
<type>text
</type>,
<type>text
</type> )
7759 <returnvalue>numeric
</returnvalue>
7762 Converts string to numeric according to the given format.
7765 <literal>to_number('
12,
454.8-', '
99G999D9S')
</literal>
7766 <returnvalue>-
12454.8</returnvalue>
7771 <entry role=
"func_table_entry"><para role=
"func_signature">
7773 <primary>to_timestamp
</primary>
7775 <function>to_timestamp
</function> (
<type>text
</type>,
<type>text
</type> )
7776 <returnvalue>timestamp with time zone
</returnvalue>
7779 Converts string to time stamp according to the given format.
7780 (See also
<function>to_timestamp(double precision)
</function> in
7781 <xref linkend=
"functions-datetime-table"/>.)
7784 <literal>to_timestamp('
05 Dec
2000', 'DD Mon YYYY')
</literal>
7785 <returnvalue>2000-
12-
05 00:
00:
00-
05</returnvalue>
7794 <function>to_timestamp
</function> and
<function>to_date
</function>
7795 exist to handle input formats that cannot be converted by
7796 simple casting. For most standard date/time formats, simply casting the
7797 source string to the required data type works, and is much easier.
7798 Similarly,
<function>to_number
</function> is unnecessary for standard numeric
7804 In a
<function>to_char
</function> output template string, there are certain
7805 patterns that are recognized and replaced with appropriately-formatted
7806 data based on the given value. Any text that is not a template pattern is
7807 simply copied verbatim. Similarly, in an input template string (for the
7808 other functions), template patterns identify the values to be supplied by
7809 the input data string. If there are characters in the template string
7810 that are not template patterns, the corresponding characters in the input
7811 data string are simply skipped over (whether or not they are equal to the
7812 template string characters).
7816 <xref linkend=
"functions-formatting-datetime-table"/> shows the
7817 template patterns available for formatting date and time values.
7820 <table id=
"functions-formatting-datetime-table">
7821 <title>Template Patterns for Date/Time Formatting
</title>
7825 <entry>Pattern
</entry>
7826 <entry>Description
</entry>
7831 <entry><literal>HH
</literal></entry>
7832 <entry>hour of day (
01–12)
</entry>
7835 <entry><literal>HH12
</literal></entry>
7836 <entry>hour of day (
01–12)
</entry>
7839 <entry><literal>HH24
</literal></entry>
7840 <entry>hour of day (
00–23)
</entry>
7843 <entry><literal>MI
</literal></entry>
7844 <entry>minute (
00–59)
</entry>
7847 <entry><literal>SS
</literal></entry>
7848 <entry>second (
00–59)
</entry>
7851 <entry><literal>MS
</literal></entry>
7852 <entry>millisecond (
000–999)
</entry>
7855 <entry><literal>US
</literal></entry>
7856 <entry>microsecond (
000000–999999)
</entry>
7859 <entry><literal>FF1
</literal></entry>
7860 <entry>tenth of second (
0–9)
</entry>
7863 <entry><literal>FF2
</literal></entry>
7864 <entry>hundredth of second (
00–99)
</entry>
7867 <entry><literal>FF3
</literal></entry>
7868 <entry>millisecond (
000–999)
</entry>
7871 <entry><literal>FF4
</literal></entry>
7872 <entry>tenth of a millisecond (
0000–9999)
</entry>
7875 <entry><literal>FF5
</literal></entry>
7876 <entry>hundredth of a millisecond (
00000–99999)
</entry>
7879 <entry><literal>FF6
</literal></entry>
7880 <entry>microsecond (
000000–999999)
</entry>
7883 <entry><literal>SSSS
</literal>,
<literal>SSSSS
</literal></entry>
7884 <entry>seconds past midnight (
0–86399)
</entry>
7887 <entry><literal>AM
</literal>,
<literal>am
</literal>,
7888 <literal>PM
</literal> or
<literal>pm
</literal></entry>
7889 <entry>meridiem indicator (without periods)
</entry>
7892 <entry><literal>A.M.
</literal>,
<literal>a.m.
</literal>,
7893 <literal>P.M.
</literal> or
<literal>p.m.
</literal></entry>
7894 <entry>meridiem indicator (with periods)
</entry>
7897 <entry><literal>Y,YYY
</literal></entry>
7898 <entry>year (
4 or more digits) with comma
</entry>
7901 <entry><literal>YYYY
</literal></entry>
7902 <entry>year (
4 or more digits)
</entry>
7905 <entry><literal>YYY
</literal></entry>
7906 <entry>last
3 digits of year
</entry>
7909 <entry><literal>YY
</literal></entry>
7910 <entry>last
2 digits of year
</entry>
7913 <entry><literal>Y
</literal></entry>
7914 <entry>last digit of year
</entry>
7917 <entry><literal>IYYY
</literal></entry>
7918 <entry>ISO
8601 week-numbering year (
4 or more digits)
</entry>
7921 <entry><literal>IYY
</literal></entry>
7922 <entry>last
3 digits of ISO
8601 week-numbering year
</entry>
7925 <entry><literal>IY
</literal></entry>
7926 <entry>last
2 digits of ISO
8601 week-numbering year
</entry>
7929 <entry><literal>I
</literal></entry>
7930 <entry>last digit of ISO
8601 week-numbering year
</entry>
7933 <entry><literal>BC
</literal>,
<literal>bc
</literal>,
7934 <literal>AD
</literal> or
<literal>ad
</literal></entry>
7935 <entry>era indicator (without periods)
</entry>
7938 <entry><literal>B.C.
</literal>,
<literal>b.c.
</literal>,
7939 <literal>A.D.
</literal> or
<literal>a.d.
</literal></entry>
7940 <entry>era indicator (with periods)
</entry>
7943 <entry><literal>MONTH
</literal></entry>
7944 <entry>full upper case month name (blank-padded to
9 chars)
</entry>
7947 <entry><literal>Month
</literal></entry>
7948 <entry>full capitalized month name (blank-padded to
9 chars)
</entry>
7951 <entry><literal>month
</literal></entry>
7952 <entry>full lower case month name (blank-padded to
9 chars)
</entry>
7955 <entry><literal>MON
</literal></entry>
7956 <entry>abbreviated upper case month name (
3 chars in English, localized lengths vary)
</entry>
7959 <entry><literal>Mon
</literal></entry>
7960 <entry>abbreviated capitalized month name (
3 chars in English, localized lengths vary)
</entry>
7963 <entry><literal>mon
</literal></entry>
7964 <entry>abbreviated lower case month name (
3 chars in English, localized lengths vary)
</entry>
7967 <entry><literal>MM
</literal></entry>
7968 <entry>month number (
01–12)
</entry>
7971 <entry><literal>DAY
</literal></entry>
7972 <entry>full upper case day name (blank-padded to
9 chars)
</entry>
7975 <entry><literal>Day
</literal></entry>
7976 <entry>full capitalized day name (blank-padded to
9 chars)
</entry>
7979 <entry><literal>day
</literal></entry>
7980 <entry>full lower case day name (blank-padded to
9 chars)
</entry>
7983 <entry><literal>DY
</literal></entry>
7984 <entry>abbreviated upper case day name (
3 chars in English, localized lengths vary)
</entry>
7987 <entry><literal>Dy
</literal></entry>
7988 <entry>abbreviated capitalized day name (
3 chars in English, localized lengths vary)
</entry>
7991 <entry><literal>dy
</literal></entry>
7992 <entry>abbreviated lower case day name (
3 chars in English, localized lengths vary)
</entry>
7995 <entry><literal>DDD
</literal></entry>
7996 <entry>day of year (
001–366)
</entry>
7999 <entry><literal>IDDD
</literal></entry>
8000 <entry>day of ISO
8601 week-numbering year (
001–371; day
1 of the year is Monday of the first ISO week)
</entry>
8003 <entry><literal>DD
</literal></entry>
8004 <entry>day of month (
01–31)
</entry>
8007 <entry><literal>D
</literal></entry>
8008 <entry>day of the week, Sunday (
<literal>1</literal>) to Saturday (
<literal>7</literal>)
</entry>
8011 <entry><literal>ID
</literal></entry>
8012 <entry>ISO
8601 day of the week, Monday (
<literal>1</literal>) to Sunday (
<literal>7</literal>)
</entry>
8015 <entry><literal>W
</literal></entry>
8016 <entry>week of month (
1–5) (the first week starts on the first day of the month)
</entry>
8019 <entry><literal>WW
</literal></entry>
8020 <entry>week number of year (
1–53) (the first week starts on the first day of the year)
</entry>
8023 <entry><literal>IW
</literal></entry>
8024 <entry>week number of ISO
8601 week-numbering year (
01–53; the first Thursday of the year is in week
1)
</entry>
8027 <entry><literal>CC
</literal></entry>
8028 <entry>century (
2 digits) (the twenty-first century starts on
2001-
01-
01)
</entry>
8031 <entry><literal>J
</literal></entry>
8032 <entry>Julian Date (integer days since November
24,
4714 BC at local
8033 midnight; see
<xref linkend=
"datetime-julian-dates"/>)
</entry>
8036 <entry><literal>Q
</literal></entry>
8037 <entry>quarter
</entry>
8040 <entry><literal>RM
</literal></entry>
8041 <entry>month in upper case Roman numerals (I
–XII; I=January)
</entry>
8044 <entry><literal>rm
</literal></entry>
8045 <entry>month in lower case Roman numerals (i
–xii; i=January)
</entry>
8048 <entry><literal>TZ
</literal></entry>
8049 <entry>upper case time-zone abbreviation
8050 (only supported in
<function>to_char
</function>)
</entry>
8053 <entry><literal>tz
</literal></entry>
8054 <entry>lower case time-zone abbreviation
8055 (only supported in
<function>to_char
</function>)
</entry>
8058 <entry><literal>TZH
</literal></entry>
8059 <entry>time-zone hours
</entry>
8062 <entry><literal>TZM
</literal></entry>
8063 <entry>time-zone minutes
</entry>
8066 <entry><literal>OF
</literal></entry>
8067 <entry>time-zone offset from UTC
8068 (only supported in
<function>to_char
</function>)
</entry>
8075 Modifiers can be applied to any template pattern to alter its
8076 behavior. For example,
<literal>FMMonth
</literal>
8077 is the
<literal>Month
</literal> pattern with the
8078 <literal>FM
</literal> modifier.
8079 <xref linkend=
"functions-formatting-datetimemod-table"/> shows the
8080 modifier patterns for date/time formatting.
8083 <table id=
"functions-formatting-datetimemod-table">
8084 <title>Template Pattern Modifiers for Date/Time Formatting
</title>
8088 <entry>Modifier
</entry>
8089 <entry>Description
</entry>
8090 <entry>Example
</entry>
8095 <entry><literal>FM
</literal> prefix
</entry>
8096 <entry>fill mode (suppress leading zeroes and padding blanks)
</entry>
8097 <entry><literal>FMMonth
</literal></entry>
8100 <entry><literal>TH
</literal> suffix
</entry>
8101 <entry>upper case ordinal number suffix
</entry>
8102 <entry><literal>DDTH
</literal>, e.g.,
<literal>12TH
</literal></entry>
8105 <entry><literal>th
</literal> suffix
</entry>
8106 <entry>lower case ordinal number suffix
</entry>
8107 <entry><literal>DDth
</literal>, e.g.,
<literal>12th
</literal></entry>
8110 <entry><literal>FX
</literal> prefix
</entry>
8111 <entry>fixed format global option (see usage notes)
</entry>
8112 <entry><literal>FX
Month
DD
Day
</literal></entry>
8115 <entry><literal>TM
</literal> prefix
</entry>
8116 <entry>translation mode (use localized day and month names based on
8117 <xref linkend=
"guc-lc-time"/>)
</entry>
8118 <entry><literal>TMMonth
</literal></entry>
8121 <entry><literal>SP
</literal> suffix
</entry>
8122 <entry>spell mode (not implemented)
</entry>
8123 <entry><literal>DDSP
</literal></entry>
8130 Usage notes for date/time formatting:
8135 <literal>FM
</literal> suppresses leading zeroes and trailing blanks
8136 that would otherwise be added to make the output of a pattern be
8137 fixed-width. In
<productname>PostgreSQL
</productname>,
8138 <literal>FM
</literal> modifies only the next specification, while in
8139 Oracle
<literal>FM
</literal> affects all subsequent
8140 specifications, and repeated
<literal>FM
</literal> modifiers
8141 toggle fill mode on and off.
8147 <literal>TM
</literal> suppresses trailing blanks whether or
8148 not
<literal>FM
</literal> is specified.
8154 <function>to_timestamp
</function> and
<function>to_date
</function>
8155 ignore letter case in the input; so for
8156 example
<literal>MON
</literal>,
<literal>Mon
</literal>,
8157 and
<literal>mon
</literal> all accept the same strings. When using
8158 the
<literal>TM
</literal> modifier, case-folding is done according to
8159 the rules of the function's input collation (see
8160 <xref linkend=
"collation"/>).
8166 <function>to_timestamp
</function> and
<function>to_date
</function>
8167 skip multiple blank spaces at the beginning of the input string and
8168 around date and time values unless the
<literal>FX
</literal> option is used. For example,
8169 <literal>to_timestamp('
2000 JUN', 'YYYY MON')
</literal> and
8170 <literal>to_timestamp('
2000 - JUN', 'YYYY-MON')
</literal> work, but
8171 <literal>to_timestamp('
2000 JUN', 'FXYYYY MON')
</literal> returns an error
8172 because
<function>to_timestamp
</function> expects only a single space.
8173 <literal>FX
</literal> must be specified as the first item in
8180 A separator (a space or non-letter/non-digit character) in the template string of
8181 <function>to_timestamp
</function> and
<function>to_date
</function>
8182 matches any single separator in the input string or is skipped,
8183 unless the
<literal>FX
</literal> option is used.
8184 For example,
<literal>to_timestamp('
2000JUN', 'YYYY///MON')
</literal> and
8185 <literal>to_timestamp('
2000/JUN', 'YYYY MON')
</literal> work, but
8186 <literal>to_timestamp('
2000//JUN', 'YYYY/MON')
</literal>
8187 returns an error because the number of separators in the input string
8188 exceeds the number of separators in the template.
8191 If
<literal>FX
</literal> is specified, a separator in the template string
8192 matches exactly one character in the input string. But note that the
8193 input string character is not required to be the same as the separator from the template string.
8194 For example,
<literal>to_timestamp('
2000/JUN', 'FXYYYY MON')
</literal>
8195 works, but
<literal>to_timestamp('
2000/JUN', 'FXYYYY
MON')
</literal>
8196 returns an error because the second space in the template string consumes
8197 the letter
<literal>J
</literal> from the input string.
8203 A
<literal>TZH
</literal> template pattern can match a signed number.
8204 Without the
<literal>FX
</literal> option, minus signs may be ambiguous,
8205 and could be interpreted as a separator.
8206 This ambiguity is resolved as follows: If the number of separators before
8207 <literal>TZH
</literal> in the template string is less than the number of
8208 separators before the minus sign in the input string, the minus sign
8209 is interpreted as part of
<literal>TZH
</literal>.
8210 Otherwise, the minus sign is considered to be a separator between values.
8211 For example,
<literal>to_timestamp('
2000 -
10', 'YYYY TZH')
</literal> matches
8212 <literal>-
10</literal> to
<literal>TZH
</literal>, but
8213 <literal>to_timestamp('
2000 -
10', 'YYYY
TZH')
</literal>
8214 matches
<literal>10</literal> to
<literal>TZH
</literal>.
8220 Ordinary text is allowed in
<function>to_char
</function>
8221 templates and will be output literally. You can put a substring
8222 in double quotes to force it to be interpreted as literal text
8223 even if it contains template patterns. For example, in
8224 <literal>'
"Hello Year "YYYY'
</literal>, the
<literal>YYYY
</literal>
8225 will be replaced by the year data, but the single
<literal>Y
</literal> in
<literal>Year
</literal>
8227 In
<function>to_date
</function>,
<function>to_number
</function>,
8228 and
<function>to_timestamp
</function>, literal text and double-quoted
8229 strings result in skipping the number of characters contained in the
8230 string; for example
<literal>"XX"</literal> skips two input characters
8231 (whether or not they are
<literal>XX
</literal>).
8235 Prior to
<productname>PostgreSQL
</productname> 12, it was possible to
8236 skip arbitrary text in the input string using non-letter or non-digit
8237 characters. For example,
8238 <literal>to_timestamp('
2000y6m1d', 'yyyy-MM-DD')
</literal> used to
8239 work. Now you can only use letter characters for this purpose. For example,
8240 <literal>to_timestamp('
2000y6m1d', 'yyyytMMtDDt')
</literal> and
8241 <literal>to_timestamp('
2000y6m1d', 'yyyy
"y"MM
"m"DD
"d"')
</literal>
8242 skip
<literal>y
</literal>,
<literal>m
</literal>, and
8243 <literal>d
</literal>.
8250 If you want to have a double quote in the output you must
8251 precede it with a backslash, for example
<literal>'\
"YYYY
8252 Month\"'
</literal>.
<!-- "" font-lock sanity :-) -->
8253 Backslashes are not otherwise special outside of double-quoted
8254 strings. Within a double-quoted string, a backslash causes the
8255 next character to be taken literally, whatever it is (but this
8256 has no special effect unless the next character is a double quote
8257 or another backslash).
8263 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8264 if the year format specification is less than four digits, e.g.,
8265 <literal>YYY
</literal>, and the supplied year is less than four digits,
8266 the year will be adjusted to be nearest to the year
2020, e.g.,
8267 <literal>95</literal> becomes
1995.
8273 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8274 negative years are treated as signifying BC. If you write both a
8275 negative year and an explicit
<literal>BC
</literal> field, you get AD
8276 again. An input of year zero is treated as
1 BC.
8282 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8283 the
<literal>YYYY
</literal> conversion has a restriction when
8284 processing years with more than
4 digits. You must
8285 use some non-digit character or template after
<literal>YYYY
</literal>,
8286 otherwise the year is always interpreted as
4 digits. For example
8287 (with the year
20000):
8288 <literal>to_date('
200001131', 'YYYYMMDD')
</literal> will be
8289 interpreted as a
4-digit year; instead use a non-digit
8290 separator after the year, like
8291 <literal>to_date('
20000-
1131', 'YYYY-MMDD')
</literal> or
8292 <literal>to_date('
20000Nov31', 'YYYYMonDD')
</literal>.
8298 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8299 the
<literal>CC
</literal> (century) field is accepted but ignored
8300 if there is a
<literal>YYY
</literal>,
<literal>YYYY
</literal> or
8301 <literal>Y,YYY
</literal> field. If
<literal>CC
</literal> is used with
8302 <literal>YY
</literal> or
<literal>Y
</literal> then the result is
8303 computed as that year in the specified century. If the century is
8304 specified but the year is not, the first year of the century
8311 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8312 weekday names or numbers (
<literal>DAY
</literal>,
<literal>D
</literal>,
8313 and related field types) are accepted but are ignored for purposes of
8314 computing the result. The same is true for quarter
8315 (
<literal>Q
</literal>) fields.
8321 In
<function>to_timestamp
</function> and
<function>to_date
</function>,
8322 an ISO
8601 week-numbering date (as distinct from a Gregorian date)
8323 can be specified in one of two ways:
8327 Year, week number, and weekday: for
8328 example
<literal>to_date('
2006-
42-
4', 'IYYY-IW-ID')
</literal>
8329 returns the date
<literal>2006-
10-
19</literal>.
8330 If you omit the weekday it is assumed to be
1 (Monday).
8335 Year and day of year: for example
<literal>to_date('
2006-
291',
8336 'IYYY-IDDD')
</literal> also returns
<literal>2006-
10-
19</literal>.
8342 Attempting to enter a date using a mixture of ISO
8601 week-numbering
8343 fields and Gregorian date fields is nonsensical, and will cause an
8344 error. In the context of an ISO
8601 week-numbering year, the
8345 concept of a
<quote>month
</quote> or
<quote>day of month
</quote> has no
8346 meaning. In the context of a Gregorian year, the ISO week has no
8351 While
<function>to_date
</function> will reject a mixture of
8352 Gregorian and ISO week-numbering date
8353 fields,
<function>to_char
</function> will not, since output format
8354 specifications like
<literal>YYYY-MM-DD (IYYY-IDDD)
</literal> can be
8355 useful. But avoid writing something like
<literal>IYYY-MM-DD
</literal>;
8356 that would yield surprising results near the start of the year.
8357 (See
<xref linkend=
"functions-datetime-extract"/> for more
8365 In
<function>to_timestamp
</function>, millisecond
8366 (
<literal>MS
</literal>) or microsecond (
<literal>US
</literal>)
8367 fields are used as the
8368 seconds digits after the decimal point. For example
8369 <literal>to_timestamp('
12.3', 'SS.MS')
</literal> is not
3 milliseconds,
8370 but
300, because the conversion treats it as
12 +
0.3 seconds.
8371 So, for the format
<literal>SS.MS
</literal>, the input values
8372 <literal>12.3</literal>,
<literal>12.30</literal>,
8373 and
<literal>12.300</literal> specify the
8374 same number of milliseconds. To get three milliseconds, one must write
8375 <literal>12.003</literal>, which the conversion treats as
8376 12 +
0.003 =
12.003 seconds.
8382 <literal>to_timestamp('
15:
12:
02.020.001230', 'HH24:MI:SS.MS.US')
</literal>
8383 is
15 hours,
12 minutes, and
2 seconds +
20 milliseconds +
8384 1230 microseconds =
2.021230 seconds.
8390 <function>to_char(..., 'ID')
</function>'s day of the week numbering
8391 matches the
<function>extract(isodow from ...)
</function> function, but
8392 <function>to_char(..., 'D')
</function>'s does not match
8393 <function>extract(dow from ...)
</function>'s day numbering.
8399 <function>to_char(interval)
</function> formats
<literal>HH
</literal> and
8400 <literal>HH12
</literal> as shown on a
12-hour clock, for example zero hours
8401 and
36 hours both output as
<literal>12</literal>, while
<literal>HH24
</literal>
8402 outputs the full hour value, which can exceed
23 in
8403 an
<type>interval
</type> value.
8411 <xref linkend=
"functions-formatting-numeric-table"/> shows the
8412 template patterns available for formatting numeric values.
8415 <table id=
"functions-formatting-numeric-table">
8416 <title>Template Patterns for Numeric Formatting
</title>
8420 <entry>Pattern
</entry>
8421 <entry>Description
</entry>
8426 <entry><literal>9</literal></entry>
8427 <entry>digit position (can be dropped if insignificant)
</entry>
8430 <entry><literal>0</literal></entry>
8431 <entry>digit position (will not be dropped, even if insignificant)
</entry>
8434 <entry><literal>.
</literal> (period)
</entry>
8435 <entry>decimal point
</entry>
8438 <entry><literal>,
</literal> (comma)
</entry>
8439 <entry>group (thousands) separator
</entry>
8442 <entry><literal>PR
</literal></entry>
8443 <entry>negative value in angle brackets
</entry>
8446 <entry><literal>S
</literal></entry>
8447 <entry>sign anchored to number (uses locale)
</entry>
8450 <entry><literal>L
</literal></entry>
8451 <entry>currency symbol (uses locale)
</entry>
8454 <entry><literal>D
</literal></entry>
8455 <entry>decimal point (uses locale)
</entry>
8458 <entry><literal>G
</literal></entry>
8459 <entry>group separator (uses locale)
</entry>
8462 <entry><literal>MI
</literal></entry>
8463 <entry>minus sign in specified position (if number
< 0)
</entry>
8466 <entry><literal>PL
</literal></entry>
8467 <entry>plus sign in specified position (if number
> 0)
</entry>
8470 <entry><literal>SG
</literal></entry>
8471 <entry>plus/minus sign in specified position
</entry>
8474 <entry><literal>RN
</literal></entry>
8475 <entry>Roman numeral (input between
1 and
3999)
</entry>
8478 <entry><literal>TH
</literal> or
<literal>th
</literal></entry>
8479 <entry>ordinal number suffix
</entry>
8482 <entry><literal>V
</literal></entry>
8483 <entry>shift specified number of digits (see notes)
</entry>
8486 <entry><literal>EEEE
</literal></entry>
8487 <entry>exponent for scientific notation
</entry>
8494 Usage notes for numeric formatting:
8499 <literal>0</literal> specifies a digit position that will always be printed,
8500 even if it contains a leading/trailing zero.
<literal>9</literal> also
8501 specifies a digit position, but if it is a leading zero then it will
8502 be replaced by a space, while if it is a trailing zero and fill mode
8503 is specified then it will be deleted. (For
<function>to_number()
</function>,
8504 these two pattern characters are equivalent.)
8510 The pattern characters
<literal>S
</literal>,
<literal>L
</literal>,
<literal>D
</literal>,
8511 and
<literal>G
</literal> represent the sign, currency symbol, decimal point,
8512 and thousands separator characters defined by the current locale
8513 (see
<xref linkend=
"guc-lc-monetary"/>
8514 and
<xref linkend=
"guc-lc-numeric"/>). The pattern characters period
8515 and comma represent those exact characters, with the meanings of
8516 decimal point and thousands separator, regardless of locale.
8522 If no explicit provision is made for a sign
8523 in
<function>to_char()
</function>'s pattern, one column will be reserved for
8524 the sign, and it will be anchored to (appear just left of) the
8525 number. If
<literal>S
</literal> appears just left of some
<literal>9</literal>'s,
8526 it will likewise be anchored to the number.
8532 A sign formatted using
<literal>SG
</literal>,
<literal>PL
</literal>, or
8533 <literal>MI
</literal> is not anchored to
8534 the number; for example,
8535 <literal>to_char(-
12, 'MI9999')
</literal> produces
<literal>'-
12'
</literal>
8536 but
<literal>to_char(-
12, 'S9999')
</literal> produces
<literal>'
-
12'
</literal>.
8537 (The Oracle implementation does not allow the use of
8538 <literal>MI
</literal> before
<literal>9</literal>, but rather
8539 requires that
<literal>9</literal> precede
8540 <literal>MI
</literal>.)
8546 <literal>TH
</literal> does not convert values less than zero
8547 and does not convert fractional numbers.
8553 <literal>PL
</literal>,
<literal>SG
</literal>, and
8554 <literal>TH
</literal> are
<productname>PostgreSQL
</productname>
8561 In
<function>to_number
</function>, if non-data template patterns such
8562 as
<literal>L
</literal> or
<literal>TH
</literal> are used, the
8563 corresponding number of input characters are skipped, whether or not
8564 they match the template pattern, unless they are data characters
8565 (that is, digits, sign, decimal point, or comma). For
8566 example,
<literal>TH
</literal> would skip two non-data characters.
8572 <literal>V
</literal> with
<function>to_char
</function>
8573 multiplies the input values by
8574 <literal>10^
<replaceable>n
</replaceable></literal>, where
8575 <replaceable>n
</replaceable> is the number of digits following
8576 <literal>V
</literal>.
<literal>V
</literal> with
8577 <function>to_number
</function> divides in a similar manner.
8578 <function>to_char
</function> and
<function>to_number
</function>
8579 do not support the use of
8580 <literal>V
</literal> combined with a decimal point
8581 (e.g.,
<literal>99.9V99
</literal> is not allowed).
8587 <literal>EEEE
</literal> (scientific notation) cannot be used in
8588 combination with any of the other formatting patterns or
8589 modifiers other than digit and decimal point patterns, and must be at the end of the format string
8590 (e.g.,
<literal>9.99EEEE
</literal> is a valid pattern).
8597 Certain modifiers can be applied to any template pattern to alter its
8598 behavior. For example,
<literal>FM99.99
</literal>
8599 is the
<literal>99.99</literal> pattern with the
8600 <literal>FM
</literal> modifier.
8601 <xref linkend=
"functions-formatting-numericmod-table"/> shows the
8602 modifier patterns for numeric formatting.
8605 <table id=
"functions-formatting-numericmod-table">
8606 <title>Template Pattern Modifiers for Numeric Formatting
</title>
8610 <entry>Modifier
</entry>
8611 <entry>Description
</entry>
8612 <entry>Example
</entry>
8617 <entry><literal>FM
</literal> prefix
</entry>
8618 <entry>fill mode (suppress trailing zeroes and padding blanks)
</entry>
8619 <entry><literal>FM99.99
</literal></entry>
8622 <entry><literal>TH
</literal> suffix
</entry>
8623 <entry>upper case ordinal number suffix
</entry>
8624 <entry><literal>999TH
</literal></entry>
8627 <entry><literal>th
</literal> suffix
</entry>
8628 <entry>lower case ordinal number suffix
</entry>
8629 <entry><literal>999th
</literal></entry>
8636 <xref linkend=
"functions-formatting-examples-table"/> shows some
8637 examples of the use of the
<function>to_char
</function> function.
8640 <table id=
"functions-formatting-examples-table">
8641 <title><function>to_char
</function> Examples
</title>
8645 <entry>Expression
</entry>
8646 <entry>Result
</entry>
8651 <entry><literal>to_char(current_timestamp, 'Day,
DD
HH12:MI:SS')
</literal></entry>
8652 <entry><literal>'Tuesday
,
06 05:
39:
18'
</literal></entry>
8655 <entry><literal>to_char(current_timestamp, 'FMDay,
FMDD
HH12:MI:SS')
</literal></entry>
8656 <entry><literal>'Tuesday,
6 05:
39:
18'
</literal></entry>
8659 <entry><literal>to_char(-
0.1, '
99.99')
</literal></entry>
8660 <entry><literal>'
-
.10'
</literal></entry>
8663 <entry><literal>to_char(-
0.1, 'FM9.99')
</literal></entry>
8664 <entry><literal>'-
.1'
</literal></entry>
8667 <entry><literal>to_char(-
0.1, 'FM90.99')
</literal></entry>
8668 <entry><literal>'-
0.1'
</literal></entry>
8671 <entry><literal>to_char(
0.1, '
0.9')
</literal></entry>
8672 <entry><literal>'
0.1'
</literal></entry>
8675 <entry><literal>to_char(
12, '
9990999.9')
</literal></entry>
8676 <entry><literal>'
0012.0'
</literal></entry>
8679 <entry><literal>to_char(
12, 'FM9990999.9')
</literal></entry>
8680 <entry><literal>'
0012.'
</literal></entry>
8683 <entry><literal>to_char(
485, '
999')
</literal></entry>
8684 <entry><literal>'
485'
</literal></entry>
8687 <entry><literal>to_char(-
485, '
999')
</literal></entry>
8688 <entry><literal>'-
485'
</literal></entry>
8691 <entry><literal>to_char(
485, '
9 9 9')
</literal></entry>
8692 <entry><literal>'
4 8 5'
</literal></entry>
8695 <entry><literal>to_char(
1485, '
9,
999')
</literal></entry>
8696 <entry><literal>'
1,
485'
</literal></entry>
8699 <entry><literal>to_char(
1485, '
9G999')
</literal></entry>
8700 <entry><literal>'
1 485'
</literal></entry>
8703 <entry><literal>to_char(
148.5, '
999.999')
</literal></entry>
8704 <entry><literal>'
148.500'
</literal></entry>
8707 <entry><literal>to_char(
148.5, 'FM999.999')
</literal></entry>
8708 <entry><literal>'
148.5'
</literal></entry>
8711 <entry><literal>to_char(
148.5, 'FM999.990')
</literal></entry>
8712 <entry><literal>'
148.500'
</literal></entry>
8715 <entry><literal>to_char(
148.5, '
999D999')
</literal></entry>
8716 <entry><literal>'
148,
500'
</literal></entry>
8719 <entry><literal>to_char(
3148.5, '
9G999D999')
</literal></entry>
8720 <entry><literal>'
3 148,
500'
</literal></entry>
8723 <entry><literal>to_char(-
485, '
999S')
</literal></entry>
8724 <entry><literal>'
485-'
</literal></entry>
8727 <entry><literal>to_char(-
485, '
999MI')
</literal></entry>
8728 <entry><literal>'
485-'
</literal></entry>
8731 <entry><literal>to_char(
485, '
999MI')
</literal></entry>
8732 <entry><literal>'
485 '
</literal></entry>
8735 <entry><literal>to_char(
485, 'FM999MI')
</literal></entry>
8736 <entry><literal>'
485'
</literal></entry>
8739 <entry><literal>to_char(
485, 'PL999')
</literal></entry>
8740 <entry><literal>'+
485'
</literal></entry>
8743 <entry><literal>to_char(
485, 'SG999')
</literal></entry>
8744 <entry><literal>'+
485'
</literal></entry>
8747 <entry><literal>to_char(-
485, 'SG999')
</literal></entry>
8748 <entry><literal>'-
485'
</literal></entry>
8751 <entry><literal>to_char(-
485, '
9SG99')
</literal></entry>
8752 <entry><literal>'
4-
85'
</literal></entry>
8755 <entry><literal>to_char(-
485, '
999PR')
</literal></entry>
8756 <entry><literal>'
<485>'
</literal></entry>
8759 <entry><literal>to_char(
485, 'L999')
</literal></entry>
8760 <entry><literal>'DM
485'
</literal></entry>
8763 <entry><literal>to_char(
485, 'RN')
</literal></entry>
8764 <entry><literal>'
CDLXXXV'
</literal></entry>
8767 <entry><literal>to_char(
485, 'FMRN')
</literal></entry>
8768 <entry><literal>'CDLXXXV'
</literal></entry>
8771 <entry><literal>to_char(
5.2, 'FMRN')
</literal></entry>
8772 <entry><literal>'V'
</literal></entry>
8775 <entry><literal>to_char(
482, '
999th')
</literal></entry>
8776 <entry><literal>'
482nd'
</literal></entry>
8779 <entry><literal>to_char(
485, '
"Good number:"999')
</literal></entry>
8780 <entry><literal>'Good
number:
485'
</literal></entry>
8783 <entry><literal>to_char(
485.8, '
"Pre:"999" Post:" .999')
</literal></entry>
8784 <entry><literal>'Pre:
485 Post:
.800'
</literal></entry>
8787 <entry><literal>to_char(
12, '
99V999')
</literal></entry>
8788 <entry><literal>'
12000'
</literal></entry>
8791 <entry><literal>to_char(
12.4, '
99V999')
</literal></entry>
8792 <entry><literal>'
12400'
</literal></entry>
8795 <entry><literal>to_char(
12.45, '
99V9')
</literal></entry>
8796 <entry><literal>'
125'
</literal></entry>
8799 <entry><literal>to_char(
0.0004859, '
9.99EEEE')
</literal></entry>
8800 <entry><literal>'
4.86e-04'
</literal></entry>
8809 <sect1 id=
"functions-datetime">
8810 <title>Date/Time Functions and Operators
</title>
8813 <xref linkend=
"functions-datetime-table"/> shows the available
8814 functions for date/time value processing, with details appearing in
8815 the following subsections.
<xref
8816 linkend=
"operators-datetime-table"/> illustrates the behaviors of
8817 the basic arithmetic operators (
<literal>+
</literal>,
8818 <literal>*
</literal>, etc.). For formatting functions, refer to
8819 <xref linkend=
"functions-formatting"/>. You should be familiar with
8820 the background information on date/time data types from
<xref
8821 linkend=
"datatype-datetime"/>.
8825 In addition, the usual comparison operators shown in
8826 <xref linkend=
"functions-comparison-op-table"/> are available for the
8827 date/time types. Dates and timestamps (with or without time zone) are
8828 all comparable, while times (with or without time zone) and intervals
8829 can only be compared to other values of the same data type. When
8830 comparing a timestamp without time zone to a timestamp with time zone,
8831 the former value is assumed to be given in the time zone specified by
8832 the
<xref linkend=
"guc-timezone"/> configuration parameter, and is
8833 rotated to UTC for comparison to the latter value (which is already
8834 in UTC internally). Similarly, a date value is assumed to represent
8835 midnight in the
<varname>TimeZone
</varname> zone when comparing it
8840 All the functions and operators described below that take
<type>time
</type> or
<type>timestamp
</type>
8841 inputs actually come in two variants: one that takes
<type>time with time zone
</type> or
<type>timestamp
8842 with time zone
</type>, and one that takes
<type>time without time zone
</type> or
<type>timestamp without time zone
</type>.
8843 For brevity, these variants are not shown separately. Also, the
8844 <literal>+
</literal> and
<literal>*
</literal> operators come in commutative pairs (for
8845 example both
<type>date
</type> <literal>+
</literal> <type>integer
</type>
8846 and
<type>integer
</type> <literal>+
</literal> <type>date
</type>); we show
8847 only one of each such pair.
8850 <table id=
"operators-datetime-table">
8851 <title>Date/Time Operators
</title>
8856 <entry role=
"func_table_entry"><para role=
"func_signature">
8870 <entry role=
"func_table_entry"><para role=
"func_signature">
8871 <type>date
</type> <literal>+
</literal> <type>integer
</type>
8872 <returnvalue>date
</returnvalue>
8875 Add a number of days to a date
8878 <literal>date '
2001-
09-
28' +
7</literal>
8879 <returnvalue>2001-
10-
05</returnvalue>
8884 <entry role=
"func_table_entry"><para role=
"func_signature">
8885 <type>date
</type> <literal>+
</literal> <type>interval
</type>
8886 <returnvalue>timestamp
</returnvalue>
8889 Add an interval to a date
8892 <literal>date '
2001-
09-
28' + interval '
1 hour'
</literal>
8893 <returnvalue>2001-
09-
28 01:
00:
00</returnvalue>
8898 <entry role=
"func_table_entry"><para role=
"func_signature">
8899 <type>date
</type> <literal>+
</literal> <type>time
</type>
8900 <returnvalue>timestamp
</returnvalue>
8903 Add a time-of-day to a date
8906 <literal>date '
2001-
09-
28' + time '
03:
00'
</literal>
8907 <returnvalue>2001-
09-
28 03:
00:
00</returnvalue>
8912 <entry role=
"func_table_entry"><para role=
"func_signature">
8913 <type>interval
</type> <literal>+
</literal> <type>interval
</type>
8914 <returnvalue>interval
</returnvalue>
8920 <literal>interval '
1 day' + interval '
1 hour'
</literal>
8921 <returnvalue>1 day
01:
00:
00</returnvalue>
8926 <entry role=
"func_table_entry"><para role=
"func_signature">
8927 <type>timestamp
</type> <literal>+
</literal> <type>interval
</type>
8928 <returnvalue>timestamp
</returnvalue>
8931 Add an interval to a timestamp
8934 <literal>timestamp '
2001-
09-
28 01:
00' + interval '
23 hours'
</literal>
8935 <returnvalue>2001-
09-
29 00:
00:
00</returnvalue>
8940 <entry role=
"func_table_entry"><para role=
"func_signature">
8941 <type>time
</type> <literal>+
</literal> <type>interval
</type>
8942 <returnvalue>time
</returnvalue>
8945 Add an interval to a time
8948 <literal>time '
01:
00' + interval '
3 hours'
</literal>
8949 <returnvalue>04:
00:
00</returnvalue>
8954 <entry role=
"func_table_entry"><para role=
"func_signature">
8955 <literal>-
</literal> <type>interval
</type>
8956 <returnvalue>interval
</returnvalue>
8962 <literal>- interval '
23 hours'
</literal>
8963 <returnvalue>-
23:
00:
00</returnvalue>
8968 <entry role=
"func_table_entry"><para role=
"func_signature">
8969 <type>date
</type> <literal>-
</literal> <type>date
</type>
8970 <returnvalue>integer
</returnvalue>
8973 Subtract dates, producing the number of days elapsed
8976 <literal>date '
2001-
10-
01' - date '
2001-
09-
28'
</literal>
8977 <returnvalue>3</returnvalue>
8982 <entry role=
"func_table_entry"><para role=
"func_signature">
8983 <type>date
</type> <literal>-
</literal> <type>integer
</type>
8984 <returnvalue>date
</returnvalue>
8987 Subtract a number of days from a date
8990 <literal>date '
2001-
10-
01' -
7</literal>
8991 <returnvalue>2001-
09-
24</returnvalue>
8996 <entry role=
"func_table_entry"><para role=
"func_signature">
8997 <type>date
</type> <literal>-
</literal> <type>interval
</type>
8998 <returnvalue>timestamp
</returnvalue>
9001 Subtract an interval from a date
9004 <literal>date '
2001-
09-
28' - interval '
1 hour'
</literal>
9005 <returnvalue>2001-
09-
27 23:
00:
00</returnvalue>
9010 <entry role=
"func_table_entry"><para role=
"func_signature">
9011 <type>time
</type> <literal>-
</literal> <type>time
</type>
9012 <returnvalue>interval
</returnvalue>
9018 <literal>time '
05:
00' - time '
03:
00'
</literal>
9019 <returnvalue>02:
00:
00</returnvalue>
9024 <entry role=
"func_table_entry"><para role=
"func_signature">
9025 <type>time
</type> <literal>-
</literal> <type>interval
</type>
9026 <returnvalue>time
</returnvalue>
9029 Subtract an interval from a time
9032 <literal>time '
05:
00' - interval '
2 hours'
</literal>
9033 <returnvalue>03:
00:
00</returnvalue>
9038 <entry role=
"func_table_entry"><para role=
"func_signature">
9039 <type>timestamp
</type> <literal>-
</literal> <type>interval
</type>
9040 <returnvalue>timestamp
</returnvalue>
9043 Subtract an interval from a timestamp
9046 <literal>timestamp '
2001-
09-
28 23:
00' - interval '
23 hours'
</literal>
9047 <returnvalue>2001-
09-
28 00:
00:
00</returnvalue>
9052 <entry role=
"func_table_entry"><para role=
"func_signature">
9053 <type>interval
</type> <literal>-
</literal> <type>interval
</type>
9054 <returnvalue>interval
</returnvalue>
9060 <literal>interval '
1 day' - interval '
1 hour'
</literal>
9061 <returnvalue>1 day -
01:
00:
00</returnvalue>
9066 <entry role=
"func_table_entry"><para role=
"func_signature">
9067 <type>timestamp
</type> <literal>-
</literal> <type>timestamp
</type>
9068 <returnvalue>interval
</returnvalue>
9071 Subtract timestamps (converting
24-hour intervals into days,
9072 similarly to
<function>justify_hours()
</function>)
9075 <literal>timestamp '
2001-
09-
29 03:
00' - timestamp '
2001-
07-
27 12:
00'
</literal>
9076 <returnvalue>63 days
15:
00:
00</returnvalue>
9081 <entry role=
"func_table_entry"><para role=
"func_signature">
9082 <type>interval
</type> <literal>*
</literal> <type>double precision
</type>
9083 <returnvalue>interval
</returnvalue>
9086 Multiply an interval by a scalar
9089 <literal>interval '
1 second' *
900</literal>
9090 <returnvalue>00:
15:
00</returnvalue>
9093 <literal>interval '
1 day' *
21</literal>
9094 <returnvalue>21 days
</returnvalue>
9097 <literal>interval '
1 hour' *
3.5</literal>
9098 <returnvalue>03:
30:
00</returnvalue>
9103 <entry role=
"func_table_entry"><para role=
"func_signature">
9104 <type>interval
</type> <literal>/
</literal> <type>double precision
</type>
9105 <returnvalue>interval
</returnvalue>
9108 Divide an interval by a scalar
9111 <literal>interval '
1 hour' /
1.5</literal>
9112 <returnvalue>00:
40:
00</returnvalue>
9119 <table id=
"functions-datetime-table">
9120 <title>Date/Time Functions
</title>
9124 <entry role=
"func_table_entry"><para role=
"func_signature">
9138 <entry role=
"func_table_entry"><para role=
"func_signature">
9140 <primary>age
</primary>
9142 <function>age
</function> (
<type>timestamp
</type>,
<type>timestamp
</type> )
9143 <returnvalue>interval
</returnvalue>
9146 Subtract arguments, producing a
<quote>symbolic
</quote> result that
9147 uses years and months, rather than just days
9150 <literal>age(timestamp '
2001-
04-
10', timestamp '
1957-
06-
13')
</literal>
9151 <returnvalue>43 years
9 mons
27 days
</returnvalue>
9156 <entry role=
"func_table_entry"><para role=
"func_signature">
9157 <function>age
</function> (
<type>timestamp
</type> )
9158 <returnvalue>interval
</returnvalue>
9161 Subtract argument from
<function>current_date
</function> (at midnight)
9164 <literal>age(timestamp '
1957-
06-
13')
</literal>
9165 <returnvalue>62 years
6 mons
10 days
</returnvalue>
9170 <entry role=
"func_table_entry"><para role=
"func_signature">
9172 <primary>clock_timestamp
</primary>
9174 <function>clock_timestamp
</function> ( )
9175 <returnvalue>timestamp with time zone
</returnvalue>
9178 Current date and time (changes during statement execution);
9179 see
<xref linkend=
"functions-datetime-current"/>
9182 <literal>clock_timestamp()
</literal>
9183 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9188 <entry role=
"func_table_entry"><para role=
"func_signature">
9190 <primary>current_date
</primary>
9192 <function>current_date
</function>
9193 <returnvalue>date
</returnvalue>
9196 Current date; see
<xref linkend=
"functions-datetime-current"/>
9199 <literal>current_date
</literal>
9200 <returnvalue>2019-
12-
23</returnvalue>
9205 <entry role=
"func_table_entry"><para role=
"func_signature">
9207 <primary>current_time
</primary>
9209 <function>current_time
</function>
9210 <returnvalue>time with time zone
</returnvalue>
9213 Current time of day; see
<xref linkend=
"functions-datetime-current"/>
9216 <literal>current_time
</literal>
9217 <returnvalue>14:
39:
53.662522-
05</returnvalue>
9222 <entry role=
"func_table_entry"><para role=
"func_signature">
9223 <function>current_time
</function> (
<type>integer
</type> )
9224 <returnvalue>time with time zone
</returnvalue>
9227 Current time of day, with limited precision;
9228 see
<xref linkend=
"functions-datetime-current"/>
9231 <literal>current_time(
2)
</literal>
9232 <returnvalue>14:
39:
53.66-
05</returnvalue>
9237 <entry role=
"func_table_entry"><para role=
"func_signature">
9239 <primary>current_timestamp
</primary>
9241 <function>current_timestamp
</function>
9242 <returnvalue>timestamp with time zone
</returnvalue>
9245 Current date and time (start of current transaction);
9246 see
<xref linkend=
"functions-datetime-current"/>
9249 <literal>current_timestamp
</literal>
9250 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9255 <entry role=
"func_table_entry"><para role=
"func_signature">
9256 <function>current_timestamp
</function> (
<type>integer
</type> )
9257 <returnvalue>timestamp with time zone
</returnvalue>
9260 Current date and time (start of current transaction), with limited precision;
9261 see
<xref linkend=
"functions-datetime-current"/>
9264 <literal>current_timestamp(
0)
</literal>
9265 <returnvalue>2019-
12-
23 14:
39:
53-
05</returnvalue>
9270 <entry role=
"func_table_entry"><para role=
"func_signature">
9272 <primary>date_add
</primary>
9274 <function>date_add
</function> (
<type>timestamp with time zone
</type>,
<type>interval
</type> <optional>,
<type>text
</type> </optional> )
9275 <returnvalue>timestamp with time zone
</returnvalue>
9278 Add an
<type>interval
</type> to a
<type>timestamp with time
9279 zone
</type>, computing times of day and daylight-savings adjustments
9280 according to the time zone named by the third argument, or the
9281 current
<xref linkend=
"guc-timezone"/> setting if that is omitted.
9282 The form with two arguments is equivalent to the
<type>timestamp with
9283 time zone
</type> <literal>+
</literal> <type>interval
</type> operator.
9286 <literal>date_add('
2021-
10-
31 00:
00:
00+
02'::timestamptz, '
1 day'::interval, 'Europe/Warsaw')
</literal>
9287 <returnvalue>2021-
10-
31 23:
00:
00+
00</returnvalue>
9292 <entry role=
"func_table_entry"><para role=
"func_signature">
9293 <function>date_bin
</function> (
<type>interval
</type>,
<type>timestamp
</type>,
<type>timestamp
</type> )
9294 <returnvalue>timestamp
</returnvalue>
9297 Bin input into specified interval aligned with specified origin; see
<xref linkend=
"functions-datetime-bin"/>
9300 <literal>date_bin('
15 minutes', timestamp '
2001-
02-
16 20:
38:
40', timestamp '
2001-
02-
16 20:
05:
00')
</literal>
9301 <returnvalue>2001-
02-
16 20:
35:
00</returnvalue>
9306 <entry role=
"func_table_entry"><para role=
"func_signature">
9308 <primary>date_part
</primary>
9310 <function>date_part
</function> (
<type>text
</type>,
<type>timestamp
</type> )
9311 <returnvalue>double precision
</returnvalue>
9314 Get timestamp subfield (equivalent to
<function>extract
</function>);
9315 see
<xref linkend=
"functions-datetime-extract"/>
9318 <literal>date_part('hour', timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9319 <returnvalue>20</returnvalue>
9324 <entry role=
"func_table_entry"><para role=
"func_signature">
9325 <function>date_part
</function> (
<type>text
</type>,
<type>interval
</type> )
9326 <returnvalue>double precision
</returnvalue>
9329 Get interval subfield (equivalent to
<function>extract
</function>);
9330 see
<xref linkend=
"functions-datetime-extract"/>
9333 <literal>date_part('month', interval '
2 years
3 months')
</literal>
9334 <returnvalue>3</returnvalue>
9339 <entry role=
"func_table_entry"><para role=
"func_signature">
9341 <primary>date_subtract
</primary>
9343 <function>date_subtract
</function> (
<type>timestamp with time zone
</type>,
<type>interval
</type> <optional>,
<type>text
</type> </optional> )
9344 <returnvalue>timestamp with time zone
</returnvalue>
9347 Subtract an
<type>interval
</type> from a
<type>timestamp with time
9348 zone
</type>, computing times of day and daylight-savings adjustments
9349 according to the time zone named by the third argument, or the
9350 current
<xref linkend=
"guc-timezone"/> setting if that is omitted.
9351 The form with two arguments is equivalent to the
<type>timestamp with
9352 time zone
</type> <literal>-
</literal> <type>interval
</type> operator.
9355 <literal>date_subtract('
2021-
11-
01 00:
00:
00+
01'::timestamptz, '
1 day'::interval, 'Europe/Warsaw')
</literal>
9356 <returnvalue>2021-
10-
30 22:
00:
00+
00</returnvalue>
9361 <entry role=
"func_table_entry"><para role=
"func_signature">
9363 <primary>date_trunc
</primary>
9365 <function>date_trunc
</function> (
<type>text
</type>,
<type>timestamp
</type> )
9366 <returnvalue>timestamp
</returnvalue>
9369 Truncate to specified precision; see
<xref linkend=
"functions-datetime-trunc"/>
9372 <literal>date_trunc('hour', timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9373 <returnvalue>2001-
02-
16 20:
00:
00</returnvalue>
9378 <entry role=
"func_table_entry"><para role=
"func_signature">
9379 <function>date_trunc
</function> (
<type>text
</type>,
<type>timestamp with time zone
</type>,
<type>text
</type> )
9380 <returnvalue>timestamp with time zone
</returnvalue>
9383 Truncate to specified precision in the specified time zone; see
9384 <xref linkend=
"functions-datetime-trunc"/>
9387 <literal>date_trunc('day', timestamptz '
2001-
02-
16 20:
38:
40+
00', 'Australia/Sydney')
</literal>
9388 <returnvalue>2001-
02-
16 13:
00:
00+
00</returnvalue>
9393 <entry role=
"func_table_entry"><para role=
"func_signature">
9394 <function>date_trunc
</function> (
<type>text
</type>,
<type>interval
</type> )
9395 <returnvalue>interval
</returnvalue>
9398 Truncate to specified precision; see
9399 <xref linkend=
"functions-datetime-trunc"/>
9402 <literal>date_trunc('hour', interval '
2 days
3 hours
40 minutes')
</literal>
9403 <returnvalue>2 days
03:
00:
00</returnvalue>
9408 <entry role=
"func_table_entry"><para role=
"func_signature">
9410 <primary>extract
</primary>
9412 <function>extract
</function> (
<parameter>field
</parameter> <literal>from
</literal> <type>timestamp
</type> )
9413 <returnvalue>numeric
</returnvalue>
9416 Get timestamp subfield; see
<xref linkend=
"functions-datetime-extract"/>
9419 <literal>extract(hour from timestamp '
2001-
02-
16 20:
38:
40')
</literal>
9420 <returnvalue>20</returnvalue>
9425 <entry role=
"func_table_entry"><para role=
"func_signature">
9426 <function>extract
</function> (
<parameter>field
</parameter> <literal>from
</literal> <type>interval
</type> )
9427 <returnvalue>numeric
</returnvalue>
9430 Get interval subfield; see
<xref linkend=
"functions-datetime-extract"/>
9433 <literal>extract(month from interval '
2 years
3 months')
</literal>
9434 <returnvalue>3</returnvalue>
9439 <entry role=
"func_table_entry"><para role=
"func_signature">
9441 <primary>isfinite
</primary>
9443 <function>isfinite
</function> (
<type>date
</type> )
9444 <returnvalue>boolean
</returnvalue>
9447 Test for finite date (not +/-infinity)
9450 <literal>isfinite(date '
2001-
02-
16')
</literal>
9451 <returnvalue>true
</returnvalue>
9456 <entry role=
"func_table_entry"><para role=
"func_signature">
9457 <function>isfinite
</function> (
<type>timestamp
</type> )
9458 <returnvalue>boolean
</returnvalue>
9461 Test for finite timestamp (not +/-infinity)
9464 <literal>isfinite(timestamp 'infinity')
</literal>
9465 <returnvalue>false
</returnvalue>
9470 <entry role=
"func_table_entry"><para role=
"func_signature">
9471 <function>isfinite
</function> (
<type>interval
</type> )
9472 <returnvalue>boolean
</returnvalue>
9475 Test for finite interval (currently always true)
9478 <literal>isfinite(interval '
4 hours')
</literal>
9479 <returnvalue>true
</returnvalue>
9484 <entry role=
"func_table_entry"><para role=
"func_signature">
9486 <primary>justify_days
</primary>
9488 <function>justify_days
</function> (
<type>interval
</type> )
9489 <returnvalue>interval
</returnvalue>
9492 Adjust interval so
30-day time periods are represented as months
9495 <literal>justify_days(interval '
35 days')
</literal>
9496 <returnvalue>1 mon
5 days
</returnvalue>
9501 <entry role=
"func_table_entry"><para role=
"func_signature">
9503 <primary>justify_hours
</primary>
9505 <function>justify_hours
</function> (
<type>interval
</type> )
9506 <returnvalue>interval
</returnvalue>
9509 Adjust interval so
24-hour time periods are represented as days
9512 <literal>justify_hours(interval '
27 hours')
</literal>
9513 <returnvalue>1 day
03:
00:
00</returnvalue>
9518 <entry role=
"func_table_entry"><para role=
"func_signature">
9520 <primary>justify_interval
</primary>
9522 <function>justify_interval
</function> (
<type>interval
</type> )
9523 <returnvalue>interval
</returnvalue>
9526 Adjust interval using
<function>justify_days
</function>
9527 and
<function>justify_hours
</function>, with additional sign
9531 <literal>justify_interval(interval '
1 mon -
1 hour')
</literal>
9532 <returnvalue>29 days
23:
00:
00</returnvalue>
9537 <entry role=
"func_table_entry"><para role=
"func_signature">
9539 <primary>localtime
</primary>
9541 <function>localtime
</function>
9542 <returnvalue>time
</returnvalue>
9545 Current time of day;
9546 see
<xref linkend=
"functions-datetime-current"/>
9549 <literal>localtime
</literal>
9550 <returnvalue>14:
39:
53.662522</returnvalue>
9555 <entry role=
"func_table_entry"><para role=
"func_signature">
9556 <function>localtime
</function> (
<type>integer
</type> )
9557 <returnvalue>time
</returnvalue>
9560 Current time of day, with limited precision;
9561 see
<xref linkend=
"functions-datetime-current"/>
9564 <literal>localtime(
0)
</literal>
9565 <returnvalue>14:
39:
53</returnvalue>
9570 <entry role=
"func_table_entry"><para role=
"func_signature">
9572 <primary>localtimestamp
</primary>
9574 <function>localtimestamp
</function>
9575 <returnvalue>timestamp
</returnvalue>
9578 Current date and time (start of current transaction);
9579 see
<xref linkend=
"functions-datetime-current"/>
9582 <literal>localtimestamp
</literal>
9583 <returnvalue>2019-
12-
23 14:
39:
53.662522</returnvalue>
9588 <entry role=
"func_table_entry"><para role=
"func_signature">
9589 <function>localtimestamp
</function> (
<type>integer
</type> )
9590 <returnvalue>timestamp
</returnvalue>
9593 Current date and time (start of current
9594 transaction), with limited precision;
9595 see
<xref linkend=
"functions-datetime-current"/>
9598 <literal>localtimestamp(
2)
</literal>
9599 <returnvalue>2019-
12-
23 14:
39:
53.66</returnvalue>
9604 <entry role=
"func_table_entry"><para role=
"func_signature">
9606 <primary>make_date
</primary>
9608 <function>make_date
</function> (
<parameter>year
</parameter> <type>int
</type>,
9609 <parameter>month
</parameter> <type>int
</type>,
9610 <parameter>day
</parameter> <type>int
</type> )
9611 <returnvalue>date
</returnvalue>
9614 Create date from year, month and day fields
9615 (negative years signify BC)
9618 <literal>make_date(
2013,
7,
15)
</literal>
9619 <returnvalue>2013-
07-
15</returnvalue>
9624 <entry role=
"func_table_entry"><para role=
"func_signature"><indexterm>
9625 <primary>make_interval
</primary>
9627 <function>make_interval
</function> (
<optional> <parameter>years
</parameter> <type>int
</type>
9628 <optional>,
<parameter>months
</parameter> <type>int
</type>
9629 <optional>,
<parameter>weeks
</parameter> <type>int
</type>
9630 <optional>,
<parameter>days
</parameter> <type>int
</type>
9631 <optional>,
<parameter>hours
</parameter> <type>int
</type>
9632 <optional>,
<parameter>mins
</parameter> <type>int
</type>
9633 <optional>,
<parameter>secs
</parameter> <type>double precision
</type>
9634 </optional></optional></optional></optional></optional></optional></optional> )
9635 <returnvalue>interval
</returnvalue>
9638 Create interval from years, months, weeks, days, hours, minutes and
9639 seconds fields, each of which can default to zero
9642 <literal>make_interval(days =
> 10)
</literal>
9643 <returnvalue>10 days
</returnvalue>
9648 <entry role=
"func_table_entry"><para role=
"func_signature">
9650 <primary>make_time
</primary>
9652 <function>make_time
</function> (
<parameter>hour
</parameter> <type>int
</type>,
9653 <parameter>min
</parameter> <type>int
</type>,
9654 <parameter>sec
</parameter> <type>double precision
</type> )
9655 <returnvalue>time
</returnvalue>
9658 Create time from hour, minute and seconds fields
9661 <literal>make_time(
8,
15,
23.5)
</literal>
9662 <returnvalue>08:
15:
23.5</returnvalue>
9667 <entry role=
"func_table_entry"><para role=
"func_signature">
9669 <primary>make_timestamp
</primary>
9671 <function>make_timestamp
</function> (
<parameter>year
</parameter> <type>int
</type>,
9672 <parameter>month
</parameter> <type>int
</type>,
9673 <parameter>day
</parameter> <type>int
</type>,
9674 <parameter>hour
</parameter> <type>int
</type>,
9675 <parameter>min
</parameter> <type>int
</type>,
9676 <parameter>sec
</parameter> <type>double precision
</type> )
9677 <returnvalue>timestamp
</returnvalue>
9680 Create timestamp from year, month, day, hour, minute and seconds fields
9681 (negative years signify BC)
9684 <literal>make_timestamp(
2013,
7,
15,
8,
15,
23.5)
</literal>
9685 <returnvalue>2013-
07-
15 08:
15:
23.5</returnvalue>
9690 <entry role=
"func_table_entry"><para role=
"func_signature">
9692 <primary>make_timestamptz
</primary>
9694 <function>make_timestamptz
</function> (
<parameter>year
</parameter> <type>int
</type>,
9695 <parameter>month
</parameter> <type>int
</type>,
9696 <parameter>day
</parameter> <type>int
</type>,
9697 <parameter>hour
</parameter> <type>int
</type>,
9698 <parameter>min
</parameter> <type>int
</type>,
9699 <parameter>sec
</parameter> <type>double precision
</type>
9700 <optional>,
<parameter>timezone
</parameter> <type>text
</type> </optional> )
9701 <returnvalue>timestamp with time zone
</returnvalue>
9704 Create timestamp with time zone from year, month, day, hour, minute
9705 and seconds fields (negative years signify BC).
9706 If
<parameter>timezone
</parameter> is not
9707 specified, the current time zone is used; the examples assume the
9708 session time zone is
<literal>Europe/London
</literal>
9711 <literal>make_timestamptz(
2013,
7,
15,
8,
15,
23.5)
</literal>
9712 <returnvalue>2013-
07-
15 08:
15:
23.5+
01</returnvalue>
9715 <literal>make_timestamptz(
2013,
7,
15,
8,
15,
23.5, 'America/New_York')
</literal>
9716 <returnvalue>2013-
07-
15 13:
15:
23.5+
01</returnvalue>
9721 <entry role=
"func_table_entry"><para role=
"func_signature">
9723 <primary>now
</primary>
9725 <function>now
</function> ( )
9726 <returnvalue>timestamp with time zone
</returnvalue>
9729 Current date and time (start of current transaction);
9730 see
<xref linkend=
"functions-datetime-current"/>
9733 <literal>now()
</literal>
9734 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9739 <entry role=
"func_table_entry"><para role=
"func_signature">
9741 <primary>statement_timestamp
</primary>
9743 <function>statement_timestamp
</function> ( )
9744 <returnvalue>timestamp with time zone
</returnvalue>
9747 Current date and time (start of current statement);
9748 see
<xref linkend=
"functions-datetime-current"/>
9751 <literal>statement_timestamp()
</literal>
9752 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9757 <entry role=
"func_table_entry"><para role=
"func_signature">
9759 <primary>timeofday
</primary>
9761 <function>timeofday
</function> ( )
9762 <returnvalue>text
</returnvalue>
9765 Current date and time
9766 (like
<function>clock_timestamp
</function>, but as a
<type>text
</type> string);
9767 see
<xref linkend=
"functions-datetime-current"/>
9770 <literal>timeofday()
</literal>
9771 <returnvalue>Mon Dec
23 14:
39:
53.662522 2019 EST
</returnvalue>
9776 <entry role=
"func_table_entry"><para role=
"func_signature">
9778 <primary>transaction_timestamp
</primary>
9780 <function>transaction_timestamp
</function> ( )
9781 <returnvalue>timestamp with time zone
</returnvalue>
9784 Current date and time (start of current transaction);
9785 see
<xref linkend=
"functions-datetime-current"/>
9788 <literal>transaction_timestamp()
</literal>
9789 <returnvalue>2019-
12-
23 14:
39:
53.662522-
05</returnvalue>
9794 <entry role=
"func_table_entry"><para role=
"func_signature">
9796 <primary>to_timestamp
</primary>
9798 <function>to_timestamp
</function> (
<type>double precision
</type> )
9799 <returnvalue>timestamp with time zone
</returnvalue>
9802 Convert Unix epoch (seconds since
1970-
01-
01 00:
00:
00+
00) to
9803 timestamp with time zone
9806 <literal>to_timestamp(
1284352323)
</literal>
9807 <returnvalue>2010-
09-
13 04:
32:
03+
00</returnvalue>
9816 <primary>OVERLAPS
</primary>
9818 In addition to these functions, the SQL
<literal>OVERLAPS
</literal> operator is
9821 (
<replaceable>start1
</replaceable>,
<replaceable>end1
</replaceable>) OVERLAPS (
<replaceable>start2
</replaceable>,
<replaceable>end2
</replaceable>)
9822 (
<replaceable>start1
</replaceable>,
<replaceable>length1
</replaceable>) OVERLAPS (
<replaceable>start2
</replaceable>,
<replaceable>length2
</replaceable>)
9824 This expression yields true when two time periods (defined by their
9825 endpoints) overlap, false when they do not overlap. The endpoints
9826 can be specified as pairs of dates, times, or time stamps; or as
9827 a date, time, or time stamp followed by an interval. When a pair
9828 of values is provided, either the start or the end can be written
9829 first;
<literal>OVERLAPS
</literal> automatically takes the earlier value
9830 of the pair as the start. Each time period is considered to
9831 represent the half-open interval
<replaceable>start
</replaceable> <literal><=
</literal>
9832 <replaceable>time
</replaceable> <literal><</literal> <replaceable>end
</replaceable>, unless
9833 <replaceable>start
</replaceable> and
<replaceable>end
</replaceable> are equal in which case it
9834 represents that single time instant. This means for instance that two
9835 time periods with only an endpoint in common do not overlap.
9839 SELECT (DATE '
2001-
02-
16', DATE '
2001-
12-
21') OVERLAPS
9840 (DATE '
2001-
10-
30', DATE '
2002-
10-
30');
9841 <lineannotation>Result:
</lineannotation><computeroutput>true
</computeroutput>
9842 SELECT (DATE '
2001-
02-
16', INTERVAL '
100 days') OVERLAPS
9843 (DATE '
2001-
10-
30', DATE '
2002-
10-
30');
9844 <lineannotation>Result:
</lineannotation><computeroutput>false
</computeroutput>
9845 SELECT (DATE '
2001-
10-
29', DATE '
2001-
10-
30') OVERLAPS
9846 (DATE '
2001-
10-
30', DATE '
2001-
10-
31');
9847 <lineannotation>Result:
</lineannotation><computeroutput>false
</computeroutput>
9848 SELECT (DATE '
2001-
10-
30', DATE '
2001-
10-
30') OVERLAPS
9849 (DATE '
2001-
10-
30', DATE '
2001-
10-
31');
9850 <lineannotation>Result:
</lineannotation><computeroutput>true
</computeroutput>
9854 When adding an
<type>interval
</type> value to (or subtracting an
9855 <type>interval
</type> value from) a
<type>timestamp
</type>
9856 or
<type>timestamp with time zone
</type> value, the months, days, and
9857 microseconds fields of the
<type>interval
</type> value are handled in turn.
9858 First, a nonzero months field advances or decrements the date of the
9859 timestamp by the indicated number of months, keeping the day of month the
9860 same unless it would be past the end of the new month, in which case the
9861 last day of that month is used. (For example, March
31 plus
1 month
9862 becomes April
30, but March
31 plus
2 months becomes May
31.)
9863 Then the days field advances or decrements the date of the timestamp by
9864 the indicated number of days. In both these steps the local time of day
9865 is kept the same. Finally, if there is a nonzero microseconds field, it
9866 is added or subtracted literally.
9867 When doing arithmetic on a
<type>timestamp with time zone
</type> value in
9868 a time zone that recognizes DST, this means that adding or subtracting
9869 (say)
<literal>interval '
1 day'
</literal> does not necessarily have the
9870 same result as adding or subtracting
<literal>interval '
24
9872 For example, with the session time zone set
9873 to
<literal>America/Denver
</literal>:
9875 SELECT timestamp with time zone '
2005-
04-
02 12:
00:
00-
07' + interval '
1 day';
9876 <lineannotation>Result:
</lineannotation><computeroutput>2005-
04-
03 12:
00:
00-
06</computeroutput>
9877 SELECT timestamp with time zone '
2005-
04-
02 12:
00:
00-
07' + interval '
24 hours';
9878 <lineannotation>Result:
</lineannotation><computeroutput>2005-
04-
03 13:
00:
00-
06</computeroutput>
9880 This happens because an hour was skipped due to a change in daylight saving
9881 time at
<literal>2005-
04-
03 02:
00:
00</literal> in time zone
9882 <literal>America/Denver
</literal>.
9886 Note there can be ambiguity in the
<literal>months
</literal> field returned by
9887 <function>age
</function> because different months have different numbers of
9888 days.
<productname>PostgreSQL
</productname>'s approach uses the month from the
9889 earlier of the two dates when calculating partial months. For example,
9890 <literal>age('
2004-
06-
01', '
2004-
04-
30')
</literal> uses April to yield
9891 <literal>1 mon
1 day
</literal>, while using May would yield
<literal>1 mon
2
9892 days
</literal> because May has
31 days, while April has only
30.
9896 Subtraction of dates and timestamps can also be complex. One conceptually
9897 simple way to perform subtraction is to convert each value to a number
9898 of seconds using
<literal>EXTRACT(EPOCH FROM ...)
</literal>, then subtract the
9899 results; this produces the
9900 number of
<emphasis>seconds
</emphasis> between the two values. This will adjust
9901 for the number of days in each month, timezone changes, and daylight
9902 saving time adjustments. Subtraction of date or timestamp
9903 values with the
<quote><literal>-
</literal></quote> operator
9904 returns the number of days (
24-hours) and hours/minutes/seconds
9905 between the values, making the same adjustments. The
<function>age
</function>
9906 function returns years, months, days, and hours/minutes/seconds,
9907 performing field-by-field subtraction and then adjusting for negative
9908 field values. The following queries illustrate the differences in these
9909 approaches. The sample results were produced with
<literal>timezone
9910 = 'US/Eastern'
</literal>; there is a daylight saving time change between the
9915 SELECT EXTRACT(EPOCH FROM timestamptz '
2013-
07-
01 12:
00:
00') -
9916 EXTRACT(EPOCH FROM timestamptz '
2013-
03-
01 12:
00:
00');
9917 <lineannotation>Result:
</lineannotation><computeroutput>10537200</computeroutput>
9918 SELECT (EXTRACT(EPOCH FROM timestamptz '
2013-
07-
01 12:
00:
00') -
9919 EXTRACT(EPOCH FROM timestamptz '
2013-
03-
01 12:
00:
00'))
9921 <lineannotation>Result:
</lineannotation><computeroutput>121.958333333333</computeroutput>
9922 SELECT timestamptz '
2013-
07-
01 12:
00:
00' - timestamptz '
2013-
03-
01 12:
00:
00';
9923 <lineannotation>Result:
</lineannotation><computeroutput>121 days
23:
00:
00</computeroutput>
9924 SELECT age(timestamptz '
2013-
07-
01 12:
00:
00', timestamptz '
2013-
03-
01 12:
00:
00');
9925 <lineannotation>Result:
</lineannotation><computeroutput>4 mons
</computeroutput>
9928 <sect2 id=
"functions-datetime-extract">
9929 <title><function>EXTRACT
</function>,
<function>date_part
</function></title>
9932 <primary>date_part
</primary>
9935 <primary>extract
</primary>
9939 EXTRACT(
<replaceable>field
</replaceable> FROM
<replaceable>source
</replaceable>)
9943 The
<function>extract
</function> function retrieves subfields
9944 such as year or hour from date/time values.
9945 <replaceable>source
</replaceable> must be a value expression of
9946 type
<type>timestamp
</type>,
<type>time
</type>, or
<type>interval
</type>.
9947 (Expressions of type
<type>date
</type> are
9948 cast to
<type>timestamp
</type> and can therefore be used as
9949 well.)
<replaceable>field
</replaceable> is an identifier or
9950 string that selects what field to extract from the source value.
9951 The
<function>extract
</function> function returns values of type
9952 <type>numeric
</type>.
9953 The following are valid field names:
9955 <!-- alphabetical -->
9958 <term><literal>century
</literal></term>
9965 SELECT EXTRACT(CENTURY FROM TIMESTAMP '
2000-
12-
16 12:
21:
13');
9966 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
9967 SELECT EXTRACT(CENTURY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
9968 <lineannotation>Result:
</lineannotation><computeroutput>21</computeroutput>
9972 The first century starts at
0001-
01-
01 00:
00:
00 AD, although
9973 they did not know it at the time. This definition applies to all
9974 Gregorian calendar countries. There is no century number
0,
9975 you go from -
1 century to
1 century.
9977 If you disagree with this, please write your complaint to:
9978 Pope, Cathedral Saint-Peter of Roma, Vatican.
9984 <term><literal>day
</literal></term>
9987 For
<type>timestamp
</type> values, the day (of the month) field
9988 (
1–31) ; for
<type>interval
</type> values, the number of days
9992 SELECT EXTRACT(DAY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
9993 <lineannotation>Result:
</lineannotation><computeroutput>16</computeroutput>
9995 SELECT EXTRACT(DAY FROM INTERVAL '
40 days
1 minute');
9996 <lineannotation>Result:
</lineannotation><computeroutput>40</computeroutput>
10003 <term><literal>decade
</literal></term>
10006 The year field divided by
10
10010 SELECT EXTRACT(DECADE FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10011 <lineannotation>Result:
</lineannotation><computeroutput>200</computeroutput>
10017 <term><literal>dow
</literal></term>
10020 The day of the week as Sunday (
<literal>0</literal>) to
10021 Saturday (
<literal>6</literal>)
10025 SELECT EXTRACT(DOW FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10026 <lineannotation>Result:
</lineannotation><computeroutput>5</computeroutput>
10029 Note that
<function>extract
</function>'s day of the week numbering
10030 differs from that of the
<function>to_char(...,
10031 'D')
</function> function.
10038 <term><literal>doy
</literal></term>
10041 The day of the year (
1–365/
366)
10045 SELECT EXTRACT(DOY FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10046 <lineannotation>Result:
</lineannotation><computeroutput>47</computeroutput>
10052 <term><literal>epoch
</literal></term>
10055 For
<type>timestamp with time zone
</type> values, the
10056 number of seconds since
1970-
01-
01 00:
00:
00 UTC (negative for
10057 timestamps before that);
10058 for
<type>date
</type> and
<type>timestamp
</type> values, the
10059 nominal number of seconds since
1970-
01-
01 00:
00:
00,
10060 without regard to timezone or daylight-savings rules;
10061 for
<type>interval
</type> values, the total number
10062 of seconds in the interval
10066 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40.12-
08');
10067 <lineannotation>Result:
</lineannotation><computeroutput>982384720.12</computeroutput>
10069 SELECT EXTRACT(EPOCH FROM TIMESTAMP '
2001-
02-
16 20:
38:
40.12');
10070 <lineannotation>Result:
</lineannotation><computeroutput>982355920.12</computeroutput>
10072 SELECT EXTRACT(EPOCH FROM INTERVAL '
5 days
3 hours');
10073 <lineannotation>Result:
</lineannotation><computeroutput>442800</computeroutput>
10077 You can convert an epoch value back to a
<type>timestamp with time zone
</type>
10078 with
<function>to_timestamp
</function>:
10081 SELECT to_timestamp(
982384720.12);
10082 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
17 04:
38:
40.12+
00</computeroutput>
10086 Beware that applying
<function>to_timestamp
</function> to an epoch
10087 extracted from a
<type>date
</type> or
<type>timestamp
</type> value
10088 could produce a misleading result: the result will effectively
10089 assume that the original value had been given in UTC, which might
10096 <term><literal>hour
</literal></term>
10099 The hour field (
0–23)
10103 SELECT EXTRACT(HOUR FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10104 <lineannotation>Result:
</lineannotation><computeroutput>20</computeroutput>
10110 <term><literal>isodow
</literal></term>
10113 The day of the week as Monday (
<literal>1</literal>) to
10114 Sunday (
<literal>7</literal>)
10118 SELECT EXTRACT(ISODOW FROM TIMESTAMP '
2001-
02-
18 20:
38:
40');
10119 <lineannotation>Result:
</lineannotation><computeroutput>7</computeroutput>
10122 This is identical to
<literal>dow
</literal> except for Sunday. This
10123 matches the
<acronym>ISO
</acronym> 8601 day of the week numbering.
10130 <term><literal>isoyear
</literal></term>
10133 The
<acronym>ISO
</acronym> 8601 week-numbering year that the date
10134 falls in (not applicable to intervals)
10138 SELECT EXTRACT(ISOYEAR FROM DATE '
2006-
01-
01');
10139 <lineannotation>Result:
</lineannotation><computeroutput>2005</computeroutput>
10140 SELECT EXTRACT(ISOYEAR FROM DATE '
2006-
01-
02');
10141 <lineannotation>Result:
</lineannotation><computeroutput>2006</computeroutput>
10145 Each
<acronym>ISO
</acronym> 8601 week-numbering year begins with the
10146 Monday of the week containing the
4th of January, so in early
10147 January or late December the
<acronym>ISO
</acronym> year may be
10148 different from the Gregorian year. See the
<literal>week
</literal>
10149 field for more information.
10152 This field is not available in PostgreSQL releases prior to
8.3.
10158 <term><literal>julian
</literal></term>
10161 The
<firstterm>Julian Date
</firstterm> corresponding to the
10162 date or timestamp (not applicable to intervals). Timestamps
10163 that are not local midnight result in a fractional value. See
10164 <xref linkend=
"datetime-julian-dates"/> for more information.
10168 SELECT EXTRACT(JULIAN FROM DATE '
2006-
01-
01');
10169 <lineannotation>Result:
</lineannotation><computeroutput>2453737</computeroutput>
10170 SELECT EXTRACT(JULIAN FROM TIMESTAMP '
2006-
01-
01 12:
00');
10171 <lineannotation>Result:
</lineannotation><computeroutput>2453737.50000000000000000000</computeroutput>
10177 <term><literal>microseconds
</literal></term>
10180 The seconds field, including fractional parts, multiplied by
1
10181 000 000; note that this includes full seconds
10185 SELECT EXTRACT(MICROSECONDS FROM TIME '
17:
12:
28.5');
10186 <lineannotation>Result:
</lineannotation><computeroutput>28500000</computeroutput>
10192 <term><literal>millennium
</literal></term>
10199 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10200 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10204 Years in the
1900s are in the second millennium.
10205 The third millennium started January
1,
2001.
10211 <term><literal>milliseconds
</literal></term>
10214 The seconds field, including fractional parts, multiplied by
10215 1000. Note that this includes full seconds.
10219 SELECT EXTRACT(MILLISECONDS FROM TIME '
17:
12:
28.5');
10220 <lineannotation>Result:
</lineannotation><computeroutput>28500</computeroutput>
10226 <term><literal>minute
</literal></term>
10229 The minutes field (
0–59)
10233 SELECT EXTRACT(MINUTE FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10234 <lineannotation>Result:
</lineannotation><computeroutput>38</computeroutput>
10240 <term><literal>month
</literal></term>
10243 For
<type>timestamp
</type> values, the number of the month
10244 within the year (
1–12) ; for
<type>interval
</type> values,
10245 the number of months, modulo
12 (
0–11)
10249 SELECT EXTRACT(MONTH FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10250 <lineannotation>Result:
</lineannotation><computeroutput>2</computeroutput>
10252 SELECT EXTRACT(MONTH FROM INTERVAL '
2 years
3 months');
10253 <lineannotation>Result:
</lineannotation><computeroutput>3</computeroutput>
10255 SELECT EXTRACT(MONTH FROM INTERVAL '
2 years
13 months');
10256 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10262 <term><literal>quarter
</literal></term>
10265 The quarter of the year (
1–4) that the date is in
10269 SELECT EXTRACT(QUARTER FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10270 <lineannotation>Result:
</lineannotation><computeroutput>1</computeroutput>
10276 <term><literal>second
</literal></term>
10279 The seconds field, including any fractional seconds
10283 SELECT EXTRACT(SECOND FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10284 <lineannotation>Result:
</lineannotation><computeroutput>40</computeroutput>
10286 SELECT EXTRACT(SECOND FROM TIME '
17:
12:
28.5');
10287 <lineannotation>Result:
</lineannotation><computeroutput>28.5</computeroutput>
10292 <term><literal>timezone
</literal></term>
10295 The time zone offset from UTC, measured in seconds. Positive values
10296 correspond to time zones east of UTC, negative values to
10297 zones west of UTC. (Technically,
10298 <productname>PostgreSQL
</productname> does not use UTC because
10299 leap seconds are not handled.)
10305 <term><literal>timezone_hour
</literal></term>
10308 The hour component of the time zone offset
10314 <term><literal>timezone_minute
</literal></term>
10317 The minute component of the time zone offset
10323 <term><literal>week
</literal></term>
10326 The number of the
<acronym>ISO
</acronym> 8601 week-numbering week of
10327 the year. By definition, ISO weeks start on Mondays and the first
10328 week of a year contains January
4 of that year. In other words, the
10329 first Thursday of a year is in week
1 of that year.
10332 In the ISO week-numbering system, it is possible for early-January
10333 dates to be part of the
52nd or
53rd week of the previous year, and for
10334 late-December dates to be part of the first week of the next year.
10335 For example,
<literal>2005-
01-
01</literal> is part of the
53rd week of year
10336 2004, and
<literal>2006-
01-
01</literal> is part of the
52nd week of year
10337 2005, while
<literal>2012-
12-
31</literal> is part of the first week of
2013.
10338 It's recommended to use the
<literal>isoyear
</literal> field together with
10339 <literal>week
</literal> to get consistent results.
10343 SELECT EXTRACT(WEEK FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10344 <lineannotation>Result:
</lineannotation><computeroutput>7</computeroutput>
10350 <term><literal>year
</literal></term>
10353 The year field. Keep in mind there is no
<literal>0 AD
</literal>, so subtracting
10354 <literal>BC
</literal> years from
<literal>AD
</literal> years should be done with care.
10358 SELECT EXTRACT(YEAR FROM TIMESTAMP '
2001-
02-
16 20:
38:
40');
10359 <lineannotation>Result:
</lineannotation><computeroutput>2001</computeroutput>
10369 When the input value is +/-Infinity,
<function>extract
</function> returns
10370 +/-Infinity for monotonically-increasing fields (
<literal>epoch
</literal>,
10371 <literal>julian
</literal>,
<literal>year
</literal>,
<literal>isoyear
</literal>,
10372 <literal>decade
</literal>,
<literal>century
</literal>, and
<literal>millennium
</literal>).
10373 For other fields, NULL is returned.
<productname>PostgreSQL
</productname>
10374 versions before
9.6 returned zero for all cases of infinite input.
10379 The
<function>extract
</function> function is primarily intended
10380 for computational processing. For formatting date/time values for
10381 display, see
<xref linkend=
"functions-formatting"/>.
10385 The
<function>date_part
</function> function is modeled on the traditional
10386 <productname>Ingres
</productname> equivalent to the
10387 <acronym>SQL
</acronym>-standard function
<function>extract
</function>:
10389 date_part('
<replaceable>field
</replaceable>',
<replaceable>source
</replaceable>)
10391 Note that here the
<replaceable>field
</replaceable> parameter needs to
10392 be a string value, not a name. The valid field names for
10393 <function>date_part
</function> are the same as for
10394 <function>extract
</function>.
10395 For historical reasons, the
<function>date_part
</function> function
10396 returns values of type
<type>double precision
</type>. This can result in
10397 a loss of precision in certain uses. Using
<function>extract
</function>
10398 is recommended instead.
10402 SELECT date_part('day', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10403 <lineannotation>Result:
</lineannotation><computeroutput>16</computeroutput>
10405 SELECT date_part('hour', INTERVAL '
4 hours
3 minutes');
10406 <lineannotation>Result:
</lineannotation><computeroutput>4</computeroutput>
10411 <sect2 id=
"functions-datetime-trunc">
10412 <title><function>date_trunc
</function></title>
10415 <primary>date_trunc
</primary>
10419 The function
<function>date_trunc
</function> is conceptually
10420 similar to the
<function>trunc
</function> function for numbers.
10425 date_trunc(
<replaceable>field
</replaceable>,
<replaceable>source
</replaceable> [,
<replaceable>time_zone
</replaceable> ])
10427 <replaceable>source
</replaceable> is a value expression of type
10428 <type>timestamp
</type>,
<type>timestamp with time zone
</type>,
10429 or
<type>interval
</type>.
10430 (Values of type
<type>date
</type> and
10431 <type>time
</type> are cast automatically to
<type>timestamp
</type> or
10432 <type>interval
</type>, respectively.)
10433 <replaceable>field
</replaceable> selects to which precision to
10434 truncate the input value. The return value is likewise of type
10435 <type>timestamp
</type>,
<type>timestamp with time zone
</type>,
10436 or
<type>interval
</type>,
10437 and it has all fields that are less significant than the
10438 selected one set to zero (or one, for day and month).
10442 Valid values for
<replaceable>field
</replaceable> are:
10444 <member><literal>microseconds
</literal></member>
10445 <member><literal>milliseconds
</literal></member>
10446 <member><literal>second
</literal></member>
10447 <member><literal>minute
</literal></member>
10448 <member><literal>hour
</literal></member>
10449 <member><literal>day
</literal></member>
10450 <member><literal>week
</literal></member>
10451 <member><literal>month
</literal></member>
10452 <member><literal>quarter
</literal></member>
10453 <member><literal>year
</literal></member>
10454 <member><literal>decade
</literal></member>
10455 <member><literal>century
</literal></member>
10456 <member><literal>millennium
</literal></member>
10461 When the input value is of type
<type>timestamp with time zone
</type>,
10462 the truncation is performed with respect to a particular time zone;
10463 for example, truncation to
<literal>day
</literal> produces a value that
10464 is midnight in that zone. By default, truncation is done with respect
10465 to the current
<xref linkend=
"guc-timezone"/> setting, but the
10466 optional
<replaceable>time_zone
</replaceable> argument can be provided
10467 to specify a different time zone. The time zone name can be specified
10468 in any of the ways described in
<xref linkend=
"datatype-timezones"/>.
10472 A time zone cannot be specified when processing
<type>timestamp without
10473 time zone
</type> or
<type>interval
</type> inputs. These are always
10474 taken at face value.
10478 Examples (assuming the local time zone is
<literal>America/New_York
</literal>):
10480 SELECT date_trunc('hour', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10481 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 20:
00:
00</computeroutput>
10483 SELECT date_trunc('year', TIMESTAMP '
2001-
02-
16 20:
38:
40');
10484 <lineannotation>Result:
</lineannotation><computeroutput>2001-
01-
01 00:
00:
00</computeroutput>
10486 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40+
00');
10487 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 00:
00:
00-
05</computeroutput>
10489 SELECT date_trunc('day', TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40+
00', 'Australia/Sydney');
10490 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 08:
00:
00-
05</computeroutput>
10492 SELECT date_trunc('hour', INTERVAL '
3 days
02:
47:
33');
10493 <lineannotation>Result:
</lineannotation><computeroutput>3 days
02:
00:
00</computeroutput>
10498 <sect2 id=
"functions-datetime-bin">
10499 <title><function>date_bin
</function></title>
10502 <primary>date_bin
</primary>
10506 The function
<function>date_bin
</function> <quote>bins
</quote> the input
10507 timestamp into the specified interval (the
<firstterm>stride
</firstterm>)
10508 aligned with a specified origin.
10513 date_bin(
<replaceable>stride
</replaceable>,
<replaceable>source
</replaceable>,
<replaceable>origin
</replaceable>)
10515 <replaceable>source
</replaceable> is a value expression of type
10516 <type>timestamp
</type> or
<type>timestamp with time zone
</type>. (Values
10517 of type
<type>date
</type> are cast automatically to
10518 <type>timestamp
</type>.)
<replaceable>stride
</replaceable> is a value
10519 expression of type
<type>interval
</type>. The return value is likewise
10520 of type
<type>timestamp
</type> or
<type>timestamp with time zone
</type>,
10521 and it marks the beginning of the bin into which the
10522 <replaceable>source
</replaceable> is placed.
10528 SELECT date_bin('
15 minutes', TIMESTAMP '
2020-
02-
11 15:
44:
17', TIMESTAMP '
2001-
01-
01');
10529 <lineannotation>Result:
</lineannotation><computeroutput>2020-
02-
11 15:
30:
00</computeroutput>
10531 SELECT date_bin('
15 minutes', TIMESTAMP '
2020-
02-
11 15:
44:
17', TIMESTAMP '
2001-
01-
01 00:
02:
30');
10532 <lineannotation>Result:
</lineannotation><computeroutput>2020-
02-
11 15:
32:
30</computeroutput>
10537 In the case of full units (
1 minute,
1 hour, etc.), it gives the same result as
10538 the analogous
<function>date_trunc
</function> call, but the difference is
10539 that
<function>date_bin
</function> can truncate to an arbitrary interval.
10543 The
<parameter>stride
</parameter> interval must be greater than zero and
10544 cannot contain units of month or larger.
10548 <sect2 id=
"functions-datetime-zoneconvert">
10549 <title><literal>AT TIME ZONE
</literal></title>
10552 <primary>time zone
</primary>
10553 <secondary>conversion
</secondary>
10557 <primary>AT TIME ZONE
</primary>
10561 The
<literal>AT TIME ZONE
</literal> operator converts time
10562 stamp
<emphasis>without
</emphasis> time zone to/from
10563 time stamp
<emphasis>with
</emphasis> time zone, and
10564 <type>time with time zone
</type> values to different time
10565 zones.
<xref linkend=
"functions-datetime-zoneconvert-table"/> shows its
10569 <table id=
"functions-datetime-zoneconvert-table">
10570 <title><literal>AT TIME ZONE
</literal> Variants
</title>
10574 <entry role=
"func_table_entry"><para role=
"func_signature">
10588 <entry role=
"func_table_entry"><para role=
"func_signature">
10589 <type>timestamp without time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10590 <returnvalue>timestamp with time zone
</returnvalue>
10593 Converts given time stamp
<emphasis>without
</emphasis> time zone to
10594 time stamp
<emphasis>with
</emphasis> time zone, assuming the given
10595 value is in the named time zone.
10598 <literal>timestamp '
2001-
02-
16 20:
38:
40' at time zone 'America/Denver'
</literal>
10599 <returnvalue>2001-
02-
17 03:
38:
40+
00</returnvalue>
10604 <entry role=
"func_table_entry"><para role=
"func_signature">
10605 <type>timestamp with time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10606 <returnvalue>timestamp without time zone
</returnvalue>
10609 Converts given time stamp
<emphasis>with
</emphasis> time zone to
10610 time stamp
<emphasis>without
</emphasis> time zone, as the time would
10611 appear in that zone.
10614 <literal>timestamp with time zone '
2001-
02-
16 20:
38:
40-
05' at time zone 'America/Denver'
</literal>
10615 <returnvalue>2001-
02-
16 18:
38:
40</returnvalue>
10620 <entry role=
"func_table_entry"><para role=
"func_signature">
10621 <type>time with time zone
</type> <literal>AT TIME ZONE
</literal> <replaceable>zone
</replaceable>
10622 <returnvalue>time with time zone
</returnvalue>
10625 Converts given time
<emphasis>with
</emphasis> time zone to a new time
10626 zone. Since no date is supplied, this uses the currently active UTC
10627 offset for the named destination zone.
10630 <literal>time with time zone '
05:
34:
17-
05' at time zone 'UTC'
</literal>
10631 <returnvalue>10:
34:
17+
00</returnvalue>
10639 In these expressions, the desired time zone
<replaceable>zone
</replaceable> can be
10640 specified either as a text value (e.g.,
<literal>'America/Los_Angeles'
</literal>)
10641 or as an interval (e.g.,
<literal>INTERVAL '-
08:
00'
</literal>).
10642 In the text case, a time zone name can be specified in any of the ways
10643 described in
<xref linkend=
"datatype-timezones"/>.
10644 The interval case is only useful for zones that have fixed offsets from
10645 UTC, so it is not very common in practice.
10649 Examples (assuming the current
<xref linkend=
"guc-timezone"/> setting
10650 is
<literal>America/Los_Angeles
</literal>):
10652 SELECT TIMESTAMP '
2001-
02-
16 20:
38:
40' AT TIME ZONE 'America/Denver';
10653 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 19:
38:
40-
08</computeroutput>
10655 SELECT TIMESTAMP WITH TIME ZONE '
2001-
02-
16 20:
38:
40-
05' AT TIME ZONE 'America/Denver';
10656 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 18:
38:
40</computeroutput>
10658 SELECT TIMESTAMP '
2001-
02-
16 20:
38:
40' AT TIME ZONE 'Asia/Tokyo' AT TIME ZONE 'America/Chicago';
10659 <lineannotation>Result:
</lineannotation><computeroutput>2001-
02-
16 05:
38:
40</computeroutput>
10661 The first example adds a time zone to a value that lacks it, and
10662 displays the value using the current
<varname>TimeZone
</varname>
10663 setting. The second example shifts the time stamp with time zone value
10664 to the specified time zone, and returns the value without a time zone.
10665 This allows storage and display of values different from the current
10666 <varname>TimeZone
</varname> setting. The third example converts
10667 Tokyo time to Chicago time.
10671 The function
<literal><function>timezone
</function>(
<replaceable>zone
</replaceable>,
10672 <replaceable>timestamp
</replaceable>)
</literal> is equivalent to the SQL-conforming construct
10673 <literal><replaceable>timestamp
</replaceable> AT TIME ZONE
10674 <replaceable>zone
</replaceable></literal>.
10678 <sect2 id=
"functions-datetime-current">
10679 <title>Current Date/Time
</title>
10682 <primary>date
</primary>
10683 <secondary>current
</secondary>
10687 <primary>time
</primary>
10688 <secondary>current
</secondary>
10692 <productname>PostgreSQL
</productname> provides a number of functions
10693 that return values related to the current date and time. These
10694 SQL-standard functions all return values based on the start time of
10695 the current transaction:
10700 CURRENT_TIME(
<replaceable>precision
</replaceable>)
10701 CURRENT_TIMESTAMP(
<replaceable>precision
</replaceable>)
10704 LOCALTIME(
<replaceable>precision
</replaceable>)
10705 LOCALTIMESTAMP(
<replaceable>precision
</replaceable>)
10710 <function>CURRENT_TIME
</function> and
10711 <function>CURRENT_TIMESTAMP
</function> deliver values with time zone;
10712 <function>LOCALTIME
</function> and
10713 <function>LOCALTIMESTAMP
</function> deliver values without time zone.
10717 <function>CURRENT_TIME
</function>,
10718 <function>CURRENT_TIMESTAMP
</function>,
10719 <function>LOCALTIME
</function>, and
10720 <function>LOCALTIMESTAMP
</function>
10721 can optionally take
10722 a precision parameter, which causes the result to be rounded
10723 to that many fractional digits in the seconds field. Without a precision parameter,
10724 the result is given to the full available precision.
10730 SELECT CURRENT_TIME;
10731 <lineannotation>Result:
</lineannotation><computeroutput>14:
39:
53.662522-
05</computeroutput>
10733 SELECT CURRENT_DATE;
10734 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23</computeroutput>
10736 SELECT CURRENT_TIMESTAMP;
10737 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.662522-
05</computeroutput>
10739 SELECT CURRENT_TIMESTAMP(
2);
10740 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.66-
05</computeroutput>
10742 SELECT LOCALTIMESTAMP;
10743 <lineannotation>Result:
</lineannotation><computeroutput>2019-
12-
23 14:
39:
53.662522</computeroutput>
10748 Since these functions return
10749 the start time of the current transaction, their values do not
10750 change during the transaction. This is considered a feature:
10751 the intent is to allow a single transaction to have a consistent
10752 notion of the
<quote>current
</quote> time, so that multiple
10753 modifications within the same transaction bear the same
10759 Other database systems might advance these values more
10765 <productname>PostgreSQL
</productname> also provides functions that
10766 return the start time of the current statement, as well as the actual
10767 current time at the instant the function is called. The complete list
10768 of non-SQL-standard time functions is:
10770 transaction_timestamp()
10771 statement_timestamp()
10779 <function>transaction_timestamp()
</function> is equivalent to
10780 <function>CURRENT_TIMESTAMP
</function>, but is named to clearly reflect
10782 <function>statement_timestamp()
</function> returns the start time of the current
10783 statement (more specifically, the time of receipt of the latest command
10784 message from the client).
10785 <function>statement_timestamp()
</function> and
<function>transaction_timestamp()
</function>
10786 return the same value during the first command of a transaction, but might
10787 differ during subsequent commands.
10788 <function>clock_timestamp()
</function> returns the actual current time, and
10789 therefore its value changes even within a single SQL command.
10790 <function>timeofday()
</function> is a historical
10791 <productname>PostgreSQL
</productname> function. Like
10792 <function>clock_timestamp()
</function>, it returns the actual current time,
10793 but as a formatted
<type>text
</type> string rather than a
<type>timestamp
10794 with time zone
</type> value.
10795 <function>now()
</function> is a traditional
<productname>PostgreSQL
</productname>
10796 equivalent to
<function>transaction_timestamp()
</function>.
10800 All the date/time data types also accept the special literal value
10801 <literal>now
</literal> to specify the current date and time (again,
10802 interpreted as the transaction start time). Thus,
10803 the following three all return the same result:
10805 SELECT CURRENT_TIMESTAMP;
10807 SELECT TIMESTAMP 'now'; -- but see tip below
10813 Do not use the third form when specifying a value to be evaluated later,
10814 for example in a
<literal>DEFAULT
</literal> clause for a table column.
10815 The system will convert
<literal>now
</literal>
10816 to a
<type>timestamp
</type> as soon as the constant is parsed, so that when
10817 the default value is needed,
10818 the time of the table creation would be used! The first two
10819 forms will not be evaluated until the default value is used,
10820 because they are function calls. Thus they will give the desired
10821 behavior of defaulting to the time of row insertion.
10822 (See also
<xref linkend=
"datatype-datetime-special-values"/>.)
10827 <sect2 id=
"functions-datetime-delay">
10828 <title>Delaying Execution
</title>
10831 <primary>pg_sleep
</primary>
10834 <primary>pg_sleep_for
</primary>
10837 <primary>pg_sleep_until
</primary>
10840 <primary>sleep
</primary>
10843 <primary>delay
</primary>
10847 The following functions are available to delay execution of the server
10850 pg_sleep (
<type>double precision
</type> )
10851 pg_sleep_for (
<type>interval
</type> )
10852 pg_sleep_until (
<type>timestamp with time zone
</type> )
10855 <function>pg_sleep
</function> makes the current session's process
10856 sleep until the given number of seconds have
10857 elapsed. Fractional-second delays can be specified.
10858 <function>pg_sleep_for
</function> is a convenience function to
10859 allow the sleep time to be specified as an
<type>interval
</type>.
10860 <function>pg_sleep_until
</function> is a convenience function for when
10861 a specific wake-up time is desired.
10865 SELECT pg_sleep(
1.5);
10866 SELECT pg_sleep_for('
5 minutes');
10867 SELECT pg_sleep_until('tomorrow
03:
00');
10873 The effective resolution of the sleep interval is platform-specific;
10874 0.01 seconds is a common value. The sleep delay will be at least as long
10875 as specified. It might be longer depending on factors such as server load.
10876 In particular,
<function>pg_sleep_until
</function> is not guaranteed to
10877 wake up exactly at the specified time, but it will not wake up any earlier.
10883 Make sure that your session does not hold more locks than necessary
10884 when calling
<function>pg_sleep
</function> or its variants. Otherwise
10885 other sessions might have to wait for your sleeping process, slowing down
10894 <sect1 id=
"functions-enum">
10895 <title>Enum Support Functions
</title>
10898 For enum types (described in
<xref linkend=
"datatype-enum"/>),
10899 there are several functions that allow cleaner programming without
10900 hard-coding particular values of an enum type.
10901 These are listed in
<xref linkend=
"functions-enum-table"/>. The examples
10902 assume an enum type created as:
10905 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
10910 <table id=
"functions-enum-table">
10911 <title>Enum Support Functions
</title>
10915 <entry role=
"func_table_entry"><para role=
"func_signature">
10929 <entry role=
"func_table_entry"><para role=
"func_signature">
10931 <primary>enum_first
</primary>
10933 <function>enum_first
</function> (
<type>anyenum
</type> )
10934 <returnvalue>anyenum
</returnvalue>
10937 Returns the first value of the input enum type.
10940 <literal>enum_first(null::rainbow)
</literal>
10941 <returnvalue>red
</returnvalue>
10945 <entry role=
"func_table_entry"><para role=
"func_signature">
10947 <primary>enum_last
</primary>
10949 <function>enum_last
</function> (
<type>anyenum
</type> )
10950 <returnvalue>anyenum
</returnvalue>
10953 Returns the last value of the input enum type.
10956 <literal>enum_last(null::rainbow)
</literal>
10957 <returnvalue>purple
</returnvalue>
10961 <entry role=
"func_table_entry"><para role=
"func_signature">
10963 <primary>enum_range
</primary>
10965 <function>enum_range
</function> (
<type>anyenum
</type> )
10966 <returnvalue>anyarray
</returnvalue>
10969 Returns all values of the input enum type in an ordered array.
10972 <literal>enum_range(null::rainbow)
</literal>
10973 <returnvalue>{red,orange,yellow,
&zwsp;green,blue,purple}
</returnvalue>
10977 <entry role=
"func_table_entry"><para role=
"func_signature">
10978 <function>enum_range
</function> (
<type>anyenum
</type>,
<type>anyenum
</type> )
10979 <returnvalue>anyarray
</returnvalue>
10982 Returns the range between the two given enum values, as an ordered
10983 array. The values must be from the same enum type. If the first
10984 parameter is null, the result will start with the first value of
10986 If the second parameter is null, the result will end with the last
10987 value of the enum type.
10990 <literal>enum_range('orange'::rainbow, 'green'::rainbow)
</literal>
10991 <returnvalue>{orange,yellow,green}
</returnvalue>
10994 <literal>enum_range(NULL, 'green'::rainbow)
</literal>
10995 <returnvalue>{red,orange,
&zwsp;yellow,green}
</returnvalue>
10998 <literal>enum_range('orange'::rainbow, NULL)
</literal>
10999 <returnvalue>{orange,yellow,green,
&zwsp;blue,purple}
</returnvalue>
11007 Notice that except for the two-argument form of
<function>enum_range
</function>,
11008 these functions disregard the specific value passed to them; they care
11009 only about its declared data type. Either null or a specific value of
11010 the type can be passed, with the same result. It is more common to
11011 apply these functions to a table column or function argument than to
11012 a hardwired type name as used in the examples.
11016 <sect1 id=
"functions-geometry">
11017 <title>Geometric Functions and Operators
</title>
11020 The geometric types
<type>point
</type>,
<type>box
</type>,
11021 <type>lseg
</type>,
<type>line
</type>,
<type>path
</type>,
11022 <type>polygon
</type>, and
<type>circle
</type> have a large set of
11023 native support functions and operators, shown in
<xref
11024 linkend=
"functions-geometry-op-table"/>,
<xref
11025 linkend=
"functions-geometry-func-table"/>, and
<xref
11026 linkend=
"functions-geometry-conv-table"/>.
11029 <table id=
"functions-geometry-op-table">
11030 <title>Geometric Operators
</title>
11034 <entry role=
"func_table_entry"><para role=
"func_signature">
11048 <entry role=
"func_table_entry"><para role=
"func_signature">
11049 <replaceable>geometric_type
</replaceable> <literal>+
</literal> <type>point
</type>
11050 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11053 Adds the coordinates of the second
<type>point
</type> to those of each
11054 point of the first argument, thus performing translation.
11055 Available for
<type>point
</type>,
<type>box
</type>,
<type>path
</type>,
11056 <type>circle
</type>.
11059 <literal>box '(
1,
1),(
0,
0)' + point '(
2,
0)'
</literal>
11060 <returnvalue>(
3,
1),(
2,
0)
</returnvalue>
11065 <entry role=
"func_table_entry"><para role=
"func_signature">
11066 <type>path
</type> <literal>+
</literal> <type>path
</type>
11067 <returnvalue>path
</returnvalue>
11070 Concatenates two open paths (returns NULL if either path is closed).
11073 <literal>path '[(
0,
0),(
1,
1)]' + path '[(
2,
2),(
3,
3),(
4,
4)]'
</literal>
11074 <returnvalue>[(
0,
0),(
1,
1),(
2,
2),(
3,
3),(
4,
4)]
</returnvalue>
11079 <entry role=
"func_table_entry"><para role=
"func_signature">
11080 <replaceable>geometric_type
</replaceable> <literal>-
</literal> <type>point
</type>
11081 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11084 Subtracts the coordinates of the second
<type>point
</type> from those
11085 of each point of the first argument, thus performing translation.
11086 Available for
<type>point
</type>,
<type>box
</type>,
<type>path
</type>,
11087 <type>circle
</type>.
11090 <literal>box '(
1,
1),(
0,
0)' - point '(
2,
0)'
</literal>
11091 <returnvalue>(-
1,
1),(-
2,
0)
</returnvalue>
11096 <entry role=
"func_table_entry"><para role=
"func_signature">
11097 <replaceable>geometric_type
</replaceable> <literal>*
</literal> <type>point
</type>
11098 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11101 Multiplies each point of the first argument by the second
11102 <type>point
</type> (treating a point as being a complex number
11103 represented by real and imaginary parts, and performing standard
11104 complex multiplication). If one interprets
11105 the second
<type>point
</type> as a vector, this is equivalent to
11106 scaling the object's size and distance from the origin by the length
11107 of the vector, and rotating it counterclockwise around the origin by
11108 the vector's angle from the
<replaceable>x
</replaceable> axis.
11109 Available for
<type>point
</type>,
<type>box
</type>,
<footnote
11110 id=
"functions-geometry-rotation-fn"><para><quote>Rotating
</quote> a
11111 box with these operators only moves its corner points: the box is
11112 still considered to have sides parallel to the axes. Hence the box's
11113 size is not preserved, as a true rotation would do.
</para></footnote>
11114 <type>path
</type>,
<type>circle
</type>.
11117 <literal>path '((
0,
0),(
1,
0),(
1,
1))' * point '(
3.0,
0)'
</literal>
11118 <returnvalue>((
0,
0),(
3,
0),(
3,
3))
</returnvalue>
11121 <literal>path '((
0,
0),(
1,
0),(
1,
1))' * point(cosd(
45), sind(
45))
</literal>
11122 <returnvalue>((
0,
0),
&zwsp;(
0.7071067811865475,
0.7071067811865475),
&zwsp;(
0,
1.414213562373095))
</returnvalue>
11127 <entry role=
"func_table_entry"><para role=
"func_signature">
11128 <replaceable>geometric_type
</replaceable> <literal>/
</literal> <type>point
</type>
11129 <returnvalue><replaceable>geometric_type
</replaceable></returnvalue>
11132 Divides each point of the first argument by the second
11133 <type>point
</type> (treating a point as being a complex number
11134 represented by real and imaginary parts, and performing standard
11135 complex division). If one interprets
11136 the second
<type>point
</type> as a vector, this is equivalent to
11137 scaling the object's size and distance from the origin down by the
11138 length of the vector, and rotating it clockwise around the origin by
11139 the vector's angle from the
<replaceable>x
</replaceable> axis.
11140 Available for
<type>point
</type>,
<type>box
</type>,
<footnoteref
11141 linkend=
"functions-geometry-rotation-fn"/> <type>path
</type>,
11142 <type>circle
</type>.
11145 <literal>path '((
0,
0),(
1,
0),(
1,
1))' / point '(
2.0,
0)'
</literal>
11146 <returnvalue>((
0,
0),(
0.5,
0),(
0.5,
0.5))
</returnvalue>
11149 <literal>path '((
0,
0),(
1,
0),(
1,
1))' / point(cosd(
45), sind(
45))
</literal>
11150 <returnvalue>((
0,
0),
&zwsp;(
0.7071067811865476,-
0.7071067811865476),
&zwsp;(
1.4142135623730951,
0))
</returnvalue>
11155 <entry role=
"func_table_entry"><para role=
"func_signature">
11156 <literal>@-@
</literal> <replaceable>geometric_type
</replaceable>
11157 <returnvalue>double precision
</returnvalue>
11160 Computes the total length.
11161 Available for
<type>lseg
</type>,
<type>path
</type>.
11164 <literal>@-@ path '[(
0,
0),(
1,
0),(
1,
1)]'
</literal>
11165 <returnvalue>2</returnvalue>
11170 <entry role=
"func_table_entry"><para role=
"func_signature">
11171 <literal>@@
</literal> <replaceable>geometric_type
</replaceable>
11172 <returnvalue>point
</returnvalue>
11175 Computes the center point.
11176 Available for
<type>box
</type>,
<type>lseg
</type>,
11177 <type>polygon
</type>,
<type>circle
</type>.
11180 <literal>@@ box '(
2,
2),(
0,
0)'
</literal>
11181 <returnvalue>(
1,
1)
</returnvalue>
11186 <entry role=
"func_table_entry"><para role=
"func_signature">
11187 <literal>#
</literal> <replaceable>geometric_type
</replaceable>
11188 <returnvalue>integer
</returnvalue>
11191 Returns the number of points.
11192 Available for
<type>path
</type>,
<type>polygon
</type>.
11195 <literal># path '((
1,
0),(
0,
1),(-
1,
0))'
</literal>
11196 <returnvalue>3</returnvalue>
11201 <entry role=
"func_table_entry"><para role=
"func_signature">
11202 <replaceable>geometric_type
</replaceable> <literal>#
</literal> <replaceable>geometric_type
</replaceable>
11203 <returnvalue>point
</returnvalue>
11206 Computes the point of intersection, or NULL if there is none.
11207 Available for
<type>lseg
</type>,
<type>line
</type>.
11210 <literal>lseg '[(
0,
0),(
1,
1)]' # lseg '[(
1,
0),(
0,
1)]'
</literal>
11211 <returnvalue>(
0.5,
0.5)
</returnvalue>
11216 <entry role=
"func_table_entry"><para role=
"func_signature">
11217 <type>box
</type> <literal>#
</literal> <type>box
</type>
11218 <returnvalue>box
</returnvalue>
11221 Computes the intersection of two boxes, or NULL if there is none.
11224 <literal>box '(
2,
2),(-
1,-
1)' # box '(
1,
1),(-
2,-
2)'
</literal>
11225 <returnvalue>(
1,
1),(-
1,-
1)
</returnvalue>
11230 <entry role=
"func_table_entry"><para role=
"func_signature">
11231 <replaceable>geometric_type
</replaceable> <literal>##
</literal> <replaceable>geometric_type
</replaceable>
11232 <returnvalue>point
</returnvalue>
11235 Computes the closest point to the first object on the second object.
11236 Available for these pairs of types:
11237 (
<type>point
</type>,
<type>box
</type>),
11238 (
<type>point
</type>,
<type>lseg
</type>),
11239 (
<type>point
</type>,
<type>line
</type>),
11240 (
<type>lseg
</type>,
<type>box
</type>),
11241 (
<type>lseg
</type>,
<type>lseg
</type>),
11242 (
<type>line
</type>,
<type>lseg
</type>).
11245 <literal>point '(
0,
0)' ## lseg '[(
2,
0),(
0,
2)]'
</literal>
11246 <returnvalue>(
1,
1)
</returnvalue>
11251 <entry role=
"func_table_entry"><para role=
"func_signature">
11252 <replaceable>geometric_type
</replaceable> <literal><-
></literal> <replaceable>geometric_type
</replaceable>
11253 <returnvalue>double precision
</returnvalue>
11256 Computes the distance between the objects.
11257 Available for all seven geometric types, for all combinations
11258 of
<type>point
</type> with another geometric type, and for
11259 these additional pairs of types:
11260 (
<type>box
</type>,
<type>lseg
</type>),
11261 (
<type>lseg
</type>,
<type>line
</type>),
11262 (
<type>polygon
</type>,
<type>circle
</type>)
11263 (and the commutator cases).
11266 <literal>circle '
<(
0,
0),
1>'
<-
> circle '
<(
5,
0),
1>'
</literal>
11267 <returnvalue>3</returnvalue>
11272 <entry role=
"func_table_entry"><para role=
"func_signature">
11273 <replaceable>geometric_type
</replaceable> <literal>@
></literal> <replaceable>geometric_type
</replaceable>
11274 <returnvalue>boolean
</returnvalue>
11277 Does first object contain second?
11278 Available for these pairs of types:
11279 (
<literal>box
</literal>,
<literal>point
</literal>),
11280 (
<literal>box
</literal>,
<literal>box
</literal>),
11281 (
<literal>path
</literal>,
<literal>point
</literal>),
11282 (
<literal>polygon
</literal>,
<literal>point
</literal>),
11283 (
<literal>polygon
</literal>,
<literal>polygon
</literal>),
11284 (
<literal>circle
</literal>,
<literal>point
</literal>),
11285 (
<literal>circle
</literal>,
<literal>circle
</literal>).
11288 <literal>circle '
<(
0,
0),
2>' @
> point '(
1,
1)'
</literal>
11289 <returnvalue>t
</returnvalue>
11294 <entry role=
"func_table_entry"><para role=
"func_signature">
11295 <replaceable>geometric_type
</replaceable> <literal><@
</literal> <replaceable>geometric_type
</replaceable>
11296 <returnvalue>boolean
</returnvalue>
11299 Is first object contained in or on second?
11300 Available for these pairs of types:
11301 (
<literal>point
</literal>,
<literal>box
</literal>),
11302 (
<literal>point
</literal>,
<literal>lseg
</literal>),
11303 (
<literal>point
</literal>,
<literal>line
</literal>),
11304 (
<literal>point
</literal>,
<literal>path
</literal>),
11305 (
<literal>point
</literal>,
<literal>polygon
</literal>),
11306 (
<literal>point
</literal>,
<literal>circle
</literal>),
11307 (
<literal>box
</literal>,
<literal>box
</literal>),
11308 (
<literal>lseg
</literal>,
<literal>box
</literal>),
11309 (
<literal>lseg
</literal>,
<literal>line
</literal>),
11310 (
<literal>polygon
</literal>,
<literal>polygon
</literal>),
11311 (
<literal>circle
</literal>,
<literal>circle
</literal>).
11314 <literal>point '(
1,
1)'
<@ circle '
<(
0,
0),
2>'
</literal>
11315 <returnvalue>t
</returnvalue>
11320 <entry role=
"func_table_entry"><para role=
"func_signature">
11321 <replaceable>geometric_type
</replaceable> <literal>&&</literal> <replaceable>geometric_type
</replaceable>
11322 <returnvalue>boolean
</returnvalue>
11325 Do these objects overlap? (One point in common makes this true.)
11326 Available for
<type>box
</type>,
<type>polygon
</type>,
11327 <type>circle
</type>.
11330 <literal>box '(
1,
1),(
0,
0)'
&& box '(
2,
2),(
0,
0)'
</literal>
11331 <returnvalue>t
</returnvalue>
11336 <entry role=
"func_table_entry"><para role=
"func_signature">
11337 <replaceable>geometric_type
</replaceable> <literal><<</literal> <replaceable>geometric_type
</replaceable>
11338 <returnvalue>boolean
</returnvalue>
11341 Is first object strictly left of second?
11342 Available for
<type>point
</type>,
<type>box
</type>,
11343 <type>polygon
</type>,
<type>circle
</type>.
11346 <literal>circle '
<(
0,
0),
1>'
<< circle '
<(
5,
0),
1>'
</literal>
11347 <returnvalue>t
</returnvalue>
11352 <entry role=
"func_table_entry"><para role=
"func_signature">
11353 <replaceable>geometric_type
</replaceable> <literal>>></literal> <replaceable>geometric_type
</replaceable>
11354 <returnvalue>boolean
</returnvalue>
11357 Is first object strictly right of second?
11358 Available for
<type>point
</type>,
<type>box
</type>,
11359 <type>polygon
</type>,
<type>circle
</type>.
11362 <literal>circle '
<(
5,
0),
1>'
>> circle '
<(
0,
0),
1>'
</literal>
11363 <returnvalue>t
</returnvalue>
11368 <entry role=
"func_table_entry"><para role=
"func_signature">
11369 <replaceable>geometric_type
</replaceable> <literal>&<</literal> <replaceable>geometric_type
</replaceable>
11370 <returnvalue>boolean
</returnvalue>
11373 Does first object not extend to the right of second?
11374 Available for
<type>box
</type>,
<type>polygon
</type>,
11375 <type>circle
</type>.
11378 <literal>box '(
1,
1),(
0,
0)'
&< box '(
2,
2),(
0,
0)'
</literal>
11379 <returnvalue>t
</returnvalue>
11384 <entry role=
"func_table_entry"><para role=
"func_signature">
11385 <replaceable>geometric_type
</replaceable> <literal>&></literal> <replaceable>geometric_type
</replaceable>
11386 <returnvalue>boolean
</returnvalue>
11389 Does first object not extend to the left of second?
11390 Available for
<type>box
</type>,
<type>polygon
</type>,
11391 <type>circle
</type>.
11394 <literal>box '(
3,
3),(
0,
0)'
&> box '(
2,
2),(
0,
0)'
</literal>
11395 <returnvalue>t
</returnvalue>
11400 <entry role=
"func_table_entry"><para role=
"func_signature">
11401 <replaceable>geometric_type
</replaceable> <literal><<|
</literal> <replaceable>geometric_type
</replaceable>
11402 <returnvalue>boolean
</returnvalue>
11405 Is first object strictly below second?
11406 Available for
<type>point
</type>,
<type>box
</type>,
<type>polygon
</type>,
11407 <type>circle
</type>.
11410 <literal>box '(
3,
3),(
0,
0)'
<<| box '(
5,
5),(
3,
4)'
</literal>
11411 <returnvalue>t
</returnvalue>
11416 <entry role=
"func_table_entry"><para role=
"func_signature">
11417 <replaceable>geometric_type
</replaceable> <literal>|
>></literal> <replaceable>geometric_type
</replaceable>
11418 <returnvalue>boolean
</returnvalue>
11421 Is first object strictly above second?
11422 Available for
<type>point
</type>,
<type>box
</type>,
<type>polygon
</type>,
11423 <type>circle
</type>.
11426 <literal>box '(
5,
5),(
3,
4)' |
>> box '(
3,
3),(
0,
0)'
</literal>
11427 <returnvalue>t
</returnvalue>
11432 <entry role=
"func_table_entry"><para role=
"func_signature">
11433 <replaceable>geometric_type
</replaceable> <literal>&<|
</literal> <replaceable>geometric_type
</replaceable>
11434 <returnvalue>boolean
</returnvalue>
11437 Does first object not extend above second?
11438 Available for
<type>box
</type>,
<type>polygon
</type>,
11439 <type>circle
</type>.
11442 <literal>box '(
1,
1),(
0,
0)'
&<| box '(
2,
2),(
0,
0)'
</literal>
11443 <returnvalue>t
</returnvalue>
11448 <entry role=
"func_table_entry"><para role=
"func_signature">
11449 <replaceable>geometric_type
</replaceable> <literal>|
&></literal> <replaceable>geometric_type
</replaceable>
11450 <returnvalue>boolean
</returnvalue>
11453 Does first object not extend below second?
11454 Available for
<type>box
</type>,
<type>polygon
</type>,
11455 <type>circle
</type>.
11458 <literal>box '(
3,
3),(
0,
0)' |
&> box '(
2,
2),(
0,
0)'
</literal>
11459 <returnvalue>t
</returnvalue>
11464 <entry role=
"func_table_entry"><para role=
"func_signature">
11465 <type>box
</type> <literal><^
</literal> <type>box
</type>
11466 <returnvalue>boolean
</returnvalue>
11469 Is first object below second (allows edges to touch)?
11472 <literal>box '((
1,
1),(
0,
0))'
<^ box '((
2,
2),(
1,
1))'
</literal>
11473 <returnvalue>t
</returnvalue>
11478 <entry role=
"func_table_entry"><para role=
"func_signature">
11479 <type>box
</type> <literal>>^
</literal> <type>box
</type>
11480 <returnvalue>boolean
</returnvalue>
11483 Is first object above second (allows edges to touch)?
11486 <literal>box '((
2,
2),(
1,
1))'
>^ box '((
1,
1),(
0,
0))'
</literal>
11487 <returnvalue>t
</returnvalue>
11492 <entry role=
"func_table_entry"><para role=
"func_signature">
11493 <replaceable>geometric_type
</replaceable> <literal>?#
</literal> <replaceable>geometric_type
</replaceable>
11494 <returnvalue>boolean
</returnvalue>
11497 Do these objects intersect?
11498 Available for these pairs of types:
11499 (
<type>box
</type>,
<type>box
</type>),
11500 (
<type>lseg
</type>,
<type>box
</type>),
11501 (
<type>lseg
</type>,
<type>lseg
</type>),
11502 (
<type>lseg
</type>,
<type>line
</type>),
11503 (
<type>line
</type>,
<type>box
</type>),
11504 (
<type>line
</type>,
<type>line
</type>),
11505 (
<type>path
</type>,
<type>path
</type>).
11508 <literal>lseg '[(-
1,
0),(
1,
0)]' ?# box '(
2,
2),(-
2,-
2)'
</literal>
11509 <returnvalue>t
</returnvalue>
11514 <entry role=
"func_table_entry"><para role=
"func_signature">
11515 <literal>?-
</literal> <type>line
</type>
11516 <returnvalue>boolean
</returnvalue>
11518 <para role=
"func_signature">
11519 <literal>?-
</literal> <type>lseg
</type>
11520 <returnvalue>boolean
</returnvalue>
11523 Is line horizontal?
11526 <literal>?- lseg '[(-
1,
0),(
1,
0)]'
</literal>
11527 <returnvalue>t
</returnvalue>
11532 <entry role=
"func_table_entry"><para role=
"func_signature">
11533 <type>point
</type> <literal>?-
</literal> <type>point
</type>
11534 <returnvalue>boolean
</returnvalue>
11537 Are points horizontally aligned (that is, have same y coordinate)?
11540 <literal>point '(
1,
0)' ?- point '(
0,
0)'
</literal>
11541 <returnvalue>t
</returnvalue>
11546 <entry role=
"func_table_entry"><para role=
"func_signature">
11547 <literal>?|
</literal> <type>line
</type>
11548 <returnvalue>boolean
</returnvalue>
11550 <para role=
"func_signature">
11551 <literal>?|
</literal> <type>lseg
</type>
11552 <returnvalue>boolean
</returnvalue>
11558 <literal>?| lseg '[(-
1,
0),(
1,
0)]'
</literal>
11559 <returnvalue>f
</returnvalue>
11564 <entry role=
"func_table_entry"><para role=
"func_signature">
11565 <type>point
</type> <literal>?|
</literal> <type>point
</type>
11566 <returnvalue>boolean
</returnvalue>
11569 Are points vertically aligned (that is, have same x coordinate)?
11572 <literal>point '(
0,
1)' ?| point '(
0,
0)'
</literal>
11573 <returnvalue>t
</returnvalue>
11578 <entry role=
"func_table_entry"><para role=
"func_signature">
11579 <type>line
</type> <literal>?-|
</literal> <type>line
</type>
11580 <returnvalue>boolean
</returnvalue>
11582 <para role=
"func_signature">
11583 <type>lseg
</type> <literal>?-|
</literal> <type>lseg
</type>
11584 <returnvalue>boolean
</returnvalue>
11587 Are lines perpendicular?
11590 <literal>lseg '[(
0,
0),(
0,
1)]' ?-| lseg '[(
0,
0),(
1,
0)]'
</literal>
11591 <returnvalue>t
</returnvalue>
11596 <entry role=
"func_table_entry"><para role=
"func_signature">
11597 <type>line
</type> <literal>?||
</literal> <type>line
</type>
11598 <returnvalue>boolean
</returnvalue>
11600 <para role=
"func_signature">
11601 <type>lseg
</type> <literal>?||
</literal> <type>lseg
</type>
11602 <returnvalue>boolean
</returnvalue>
11605 Are lines parallel?
11608 <literal>lseg '[(-
1,
0),(
1,
0)]' ?|| lseg '[(-
1,
2),(
1,
2)]'
</literal>
11609 <returnvalue>t
</returnvalue>
11614 <entry role=
"func_table_entry"><para role=
"func_signature">
11615 <replaceable>geometric_type
</replaceable> <literal>~=
</literal> <replaceable>geometric_type
</replaceable>
11616 <returnvalue>boolean
</returnvalue>
11619 Are these objects the same?
11620 Available for
<type>point
</type>,
<type>box
</type>,
11621 <type>polygon
</type>,
<type>circle
</type>.
11624 <literal>polygon '((
0,
0),(
1,
1))' ~= polygon '((
1,
1),(
0,
0))'
</literal>
11625 <returnvalue>t
</returnvalue>
11634 Note that the
<quote>same as
</quote> operator,
<literal>~=
</literal>,
11635 represents the usual notion of equality for the
<type>point
</type>,
11636 <type>box
</type>,
<type>polygon
</type>, and
<type>circle
</type> types.
11637 Some of the geometric types also have an
<literal>=
</literal> operator, but
11638 <literal>=
</literal> compares for equal
<emphasis>areas
</emphasis> only.
11639 The other scalar comparison operators (
<literal><=
</literal> and so
11640 on), where available for these types, likewise compare areas.
11646 Before
<productname>PostgreSQL
</productname> 14, the point
11647 is strictly below/above comparison operators
<type>point
</type>
11648 <literal><<|
</literal> <type>point
</type> and
<type>point
</type>
11649 <literal>|
>></literal> <type>point
</type> were respectively
11650 called
<literal><^
</literal> and
<literal>>^
</literal>. These
11651 names are still available, but are deprecated and will eventually be
11656 <table id=
"functions-geometry-func-table">
11657 <title>Geometric Functions
</title>
11661 <entry role=
"func_table_entry"><para role=
"func_signature">
11675 <entry role=
"func_table_entry"><para role=
"func_signature">
11677 <primary>area
</primary>
11679 <function>area
</function> (
<replaceable>geometric_type
</replaceable> )
11680 <returnvalue>double precision
</returnvalue>
11684 Available for
<type>box
</type>,
<type>path
</type>,
<type>circle
</type>.
11685 A
<type>path
</type> input must be closed, else NULL is returned.
11686 Also, if the
<type>path
</type> is self-intersecting, the result may be
11690 <literal>area(box '(
2,
2),(
0,
0)')
</literal>
11691 <returnvalue>4</returnvalue>
11696 <entry role=
"func_table_entry"><para role=
"func_signature">
11698 <primary>center
</primary>
11700 <function>center
</function> (
<replaceable>geometric_type
</replaceable> )
11701 <returnvalue>point
</returnvalue>
11704 Computes center point.
11705 Available for
<type>box
</type>,
<type>circle
</type>.
11708 <literal>center(box '(
1,
2),(
0,
0)')
</literal>
11709 <returnvalue>(
0.5,
1)
</returnvalue>
11714 <entry role=
"func_table_entry"><para role=
"func_signature">
11716 <primary>diagonal
</primary>
11718 <function>diagonal
</function> (
<type>box
</type> )
11719 <returnvalue>lseg
</returnvalue>
11722 Extracts box's diagonal as a line segment
11723 (same as
<function>lseg(box)
</function>).
11726 <literal>diagonal(box '(
1,
2),(
0,
0)')
</literal>
11727 <returnvalue>[(
1,
2),(
0,
0)]
</returnvalue>
11732 <entry role=
"func_table_entry"><para role=
"func_signature">
11734 <primary>diameter
</primary>
11736 <function>diameter
</function> (
<type>circle
</type> )
11737 <returnvalue>double precision
</returnvalue>
11740 Computes diameter of circle.
11743 <literal>diameter(circle '
<(
0,
0),
2>')
</literal>
11744 <returnvalue>4</returnvalue>
11749 <entry role=
"func_table_entry"><para role=
"func_signature">
11751 <primary>height
</primary>
11753 <function>height
</function> (
<type>box
</type> )
11754 <returnvalue>double precision
</returnvalue>
11757 Computes vertical size of box.
11760 <literal>height(box '(
1,
2),(
0,
0)')
</literal>
11761 <returnvalue>2</returnvalue>
11766 <entry role=
"func_table_entry"><para role=
"func_signature">
11768 <primary>isclosed
</primary>
11770 <function>isclosed
</function> (
<type>path
</type> )
11771 <returnvalue>boolean
</returnvalue>
11777 <literal>isclosed(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
11778 <returnvalue>t
</returnvalue>
11783 <entry role=
"func_table_entry"><para role=
"func_signature">
11785 <primary>isopen
</primary>
11787 <function>isopen
</function> (
<type>path
</type> )
11788 <returnvalue>boolean
</returnvalue>
11794 <literal>isopen(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
11795 <returnvalue>t
</returnvalue>
11800 <entry role=
"func_table_entry"><para role=
"func_signature">
11802 <primary>length
</primary>
11804 <function>length
</function> (
<replaceable>geometric_type
</replaceable> )
11805 <returnvalue>double precision
</returnvalue>
11808 Computes the total length.
11809 Available for
<type>lseg
</type>,
<type>path
</type>.
11812 <literal>length(path '((-
1,
0),(
1,
0))')
</literal>
11813 <returnvalue>4</returnvalue>
11818 <entry role=
"func_table_entry"><para role=
"func_signature">
11820 <primary>npoints
</primary>
11822 <function>npoints
</function> (
<replaceable>geometric_type
</replaceable> )
11823 <returnvalue>integer
</returnvalue>
11826 Returns the number of points.
11827 Available for
<type>path
</type>,
<type>polygon
</type>.
11830 <literal>npoints(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
11831 <returnvalue>3</returnvalue>
11836 <entry role=
"func_table_entry"><para role=
"func_signature">
11838 <primary>pclose
</primary>
11840 <function>pclose
</function> (
<type>path
</type> )
11841 <returnvalue>path
</returnvalue>
11844 Converts path to closed form.
11847 <literal>pclose(path '[(
0,
0),(
1,
1),(
2,
0)]')
</literal>
11848 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
11853 <entry role=
"func_table_entry"><para role=
"func_signature">
11855 <primary>popen
</primary>
11857 <function>popen
</function> (
<type>path
</type> )
11858 <returnvalue>path
</returnvalue>
11861 Converts path to open form.
11864 <literal>popen(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
11865 <returnvalue>[(
0,
0),(
1,
1),(
2,
0)]
</returnvalue>
11870 <entry role=
"func_table_entry"><para role=
"func_signature">
11872 <primary>radius
</primary>
11874 <function>radius
</function> (
<type>circle
</type> )
11875 <returnvalue>double precision
</returnvalue>
11878 Computes radius of circle.
11881 <literal>radius(circle '
<(
0,
0),
2>')
</literal>
11882 <returnvalue>2</returnvalue>
11887 <entry role=
"func_table_entry"><para role=
"func_signature">
11889 <primary>slope
</primary>
11891 <function>slope
</function> (
<type>point
</type>,
<type>point
</type> )
11892 <returnvalue>double precision
</returnvalue>
11895 Computes slope of a line drawn through the two points.
11898 <literal>slope(point '(
0,
0)', point '(
2,
1)')
</literal>
11899 <returnvalue>0.5</returnvalue>
11904 <entry role=
"func_table_entry"><para role=
"func_signature">
11906 <primary>width
</primary>
11908 <function>width
</function> (
<type>box
</type> )
11909 <returnvalue>double precision
</returnvalue>
11912 Computes horizontal size of box.
11915 <literal>width(box '(
1,
2),(
0,
0)')
</literal>
11916 <returnvalue>1</returnvalue>
11923 <table id=
"functions-geometry-conv-table">
11924 <title>Geometric Type Conversion Functions
</title>
11928 <entry role=
"func_table_entry"><para role=
"func_signature">
11942 <entry role=
"func_table_entry"><para role=
"func_signature">
11944 <primary>box
</primary>
11946 <function>box
</function> (
<type>circle
</type> )
11947 <returnvalue>box
</returnvalue>
11950 Computes box inscribed within the circle.
11953 <literal>box(circle '
<(
0,
0),
2>')
</literal>
11954 <returnvalue>(
1.414213562373095,
1.414213562373095),
&zwsp;(-
1.414213562373095,-
1.414213562373095)
</returnvalue>
11959 <entry role=
"func_table_entry"><para role=
"func_signature">
11960 <function>box
</function> (
<type>point
</type> )
11961 <returnvalue>box
</returnvalue>
11964 Converts point to empty box.
11967 <literal>box(point '(
1,
0)')
</literal>
11968 <returnvalue>(
1,
0),(
1,
0)
</returnvalue>
11973 <entry role=
"func_table_entry"><para role=
"func_signature">
11974 <function>box
</function> (
<type>point
</type>,
<type>point
</type> )
11975 <returnvalue>box
</returnvalue>
11978 Converts any two corner points to box.
11981 <literal>box(point '(
0,
1)', point '(
1,
0)')
</literal>
11982 <returnvalue>(
1,
1),(
0,
0)
</returnvalue>
11987 <entry role=
"func_table_entry"><para role=
"func_signature">
11988 <function>box
</function> (
<type>polygon
</type> )
11989 <returnvalue>box
</returnvalue>
11992 Computes bounding box of polygon.
11995 <literal>box(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
11996 <returnvalue>(
2,
1),(
0,
0)
</returnvalue>
12001 <entry role=
"func_table_entry"><para role=
"func_signature">
12003 <primary>bound_box
</primary>
12005 <function>bound_box
</function> (
<type>box
</type>,
<type>box
</type> )
12006 <returnvalue>box
</returnvalue>
12009 Computes bounding box of two boxes.
12012 <literal>bound_box(box '(
1,
1),(
0,
0)', box '(
4,
4),(
3,
3)')
</literal>
12013 <returnvalue>(
4,
4),(
0,
0)
</returnvalue>
12018 <entry role=
"func_table_entry"><para role=
"func_signature">
12020 <primary>circle
</primary>
12022 <function>circle
</function> (
<type>box
</type> )
12023 <returnvalue>circle
</returnvalue>
12026 Computes smallest circle enclosing box.
12029 <literal>circle(box '(
1,
1),(
0,
0)')
</literal>
12030 <returnvalue><(
0.5,
0.5),
0.7071067811865476></returnvalue>
12035 <entry role=
"func_table_entry"><para role=
"func_signature">
12036 <function>circle
</function> (
<type>point
</type>,
<type>double precision
</type> )
12037 <returnvalue>circle
</returnvalue>
12040 Constructs circle from center and radius.
12043 <literal>circle(point '(
0,
0)',
2.0)
</literal>
12044 <returnvalue><(
0,
0),
2></returnvalue>
12049 <entry role=
"func_table_entry"><para role=
"func_signature">
12050 <function>circle
</function> (
<type>polygon
</type> )
12051 <returnvalue>circle
</returnvalue>
12054 Converts polygon to circle. The circle's center is the mean of the
12055 positions of the polygon's points, and the radius is the average
12056 distance of the polygon's points from that center.
12059 <literal>circle(polygon '((
0,
0),(
1,
3),(
2,
0))')
</literal>
12060 <returnvalue><(
1,
1),
1.6094757082487299></returnvalue>
12065 <entry role=
"func_table_entry"><para role=
"func_signature">
12067 <primary>line
</primary>
12069 <function>line
</function> (
<type>point
</type>,
<type>point
</type> )
12070 <returnvalue>line
</returnvalue>
12073 Converts two points to the line through them.
12076 <literal>line(point '(-
1,
0)', point '(
1,
0)')
</literal>
12077 <returnvalue>{
0,-
1,
0}
</returnvalue>
12082 <entry role=
"func_table_entry"><para role=
"func_signature">
12084 <primary>lseg
</primary>
12086 <function>lseg
</function> (
<type>box
</type> )
12087 <returnvalue>lseg
</returnvalue>
12090 Extracts box's diagonal as a line segment.
12093 <literal>lseg(box '(
1,
0),(-
1,
0)')
</literal>
12094 <returnvalue>[(
1,
0),(-
1,
0)]
</returnvalue>
12099 <entry role=
"func_table_entry"><para role=
"func_signature">
12100 <function>lseg
</function> (
<type>point
</type>,
<type>point
</type> )
12101 <returnvalue>lseg
</returnvalue>
12104 Constructs line segment from two endpoints.
12107 <literal>lseg(point '(-
1,
0)', point '(
1,
0)')
</literal>
12108 <returnvalue>[(-
1,
0),(
1,
0)]
</returnvalue>
12113 <entry role=
"func_table_entry"><para role=
"func_signature">
12115 <primary>path
</primary>
12117 <function>path
</function> (
<type>polygon
</type> )
12118 <returnvalue>path
</returnvalue>
12121 Converts polygon to a closed path with the same list of points.
12124 <literal>path(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12125 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12130 <entry role=
"func_table_entry"><para role=
"func_signature">
12132 <primary>point
</primary>
12134 <function>point
</function> (
<type>double precision
</type>,
<type>double precision
</type> )
12135 <returnvalue>point
</returnvalue>
12138 Constructs point from its coordinates.
12141 <literal>point(
23.4, -
44.5)
</literal>
12142 <returnvalue>(
23.4,-
44.5)
</returnvalue>
12147 <entry role=
"func_table_entry"><para role=
"func_signature">
12148 <function>point
</function> (
<type>box
</type> )
12149 <returnvalue>point
</returnvalue>
12152 Computes center of box.
12155 <literal>point(box '(
1,
0),(-
1,
0)')
</literal>
12156 <returnvalue>(
0,
0)
</returnvalue>
12161 <entry role=
"func_table_entry"><para role=
"func_signature">
12162 <function>point
</function> (
<type>circle
</type> )
12163 <returnvalue>point
</returnvalue>
12166 Computes center of circle.
12169 <literal>point(circle '
<(
0,
0),
2>')
</literal>
12170 <returnvalue>(
0,
0)
</returnvalue>
12175 <entry role=
"func_table_entry"><para role=
"func_signature">
12176 <function>point
</function> (
<type>lseg
</type> )
12177 <returnvalue>point
</returnvalue>
12180 Computes center of line segment.
12183 <literal>point(lseg '[(-
1,
0),(
1,
0)]')
</literal>
12184 <returnvalue>(
0,
0)
</returnvalue>
12189 <entry role=
"func_table_entry"><para role=
"func_signature">
12190 <function>point
</function> (
<type>polygon
</type> )
12191 <returnvalue>point
</returnvalue>
12194 Computes center of polygon (the mean of the
12195 positions of the polygon's points).
12198 <literal>point(polygon '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12199 <returnvalue>(
1,
0.3333333333333333)
</returnvalue>
12204 <entry role=
"func_table_entry"><para role=
"func_signature">
12206 <primary>polygon
</primary>
12208 <function>polygon
</function> (
<type>box
</type> )
12209 <returnvalue>polygon
</returnvalue>
12212 Converts box to a
4-point polygon.
12215 <literal>polygon(box '(
1,
1),(
0,
0)')
</literal>
12216 <returnvalue>((
0,
0),(
0,
1),(
1,
1),(
1,
0))
</returnvalue>
12221 <entry role=
"func_table_entry"><para role=
"func_signature">
12222 <function>polygon
</function> (
<type>circle
</type> )
12223 <returnvalue>polygon
</returnvalue>
12226 Converts circle to a
12-point polygon.
12229 <literal>polygon(circle '
<(
0,
0),
2>')
</literal>
12230 <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>
12235 <entry role=
"func_table_entry"><para role=
"func_signature">
12236 <function>polygon
</function> (
<type>integer
</type>,
<type>circle
</type> )
12237 <returnvalue>polygon
</returnvalue>
12240 Converts circle to an
<replaceable>n
</replaceable>-point polygon.
12243 <literal>polygon(
4, circle '
<(
3,
0),
1>')
</literal>
12244 <returnvalue>((
2,
0),
&zwsp;(
3,
1),
&zwsp;(
4,
1.2246063538223773e-16),
&zwsp;(
3,-
1))
</returnvalue>
12249 <entry role=
"func_table_entry"><para role=
"func_signature">
12250 <function>polygon
</function> (
<type>path
</type> )
12251 <returnvalue>polygon
</returnvalue>
12254 Converts closed path to a polygon with the same list of points.
12257 <literal>polygon(path '((
0,
0),(
1,
1),(
2,
0))')
</literal>
12258 <returnvalue>((
0,
0),(
1,
1),(
2,
0))
</returnvalue>
12267 It is possible to access the two component numbers of a
<type>point
</type>
12268 as though the point were an array with indexes
0 and
1. For example, if
12269 <literal>t.p
</literal> is a
<type>point
</type> column then
12270 <literal>SELECT p[
0] FROM t
</literal> retrieves the X coordinate and
12271 <literal>UPDATE t SET p[
1] = ...
</literal> changes the Y coordinate.
12272 In the same way, a value of type
<type>box
</type> or
<type>lseg
</type> can be treated
12273 as an array of two
<type>point
</type> values.
12279 <sect1 id=
"functions-net">
12280 <title>Network Address Functions and Operators
</title>
12283 The IP network address types,
<type>cidr
</type> and
<type>inet
</type>,
12284 support the usual comparison operators shown in
12285 <xref linkend=
"functions-comparison-op-table"/>
12286 as well as the specialized operators and functions shown in
12287 <xref linkend=
"cidr-inet-operators-table"/> and
12288 <xref linkend=
"cidr-inet-functions-table"/>.
12292 Any
<type>cidr
</type> value can be cast to
<type>inet
</type> implicitly;
12293 therefore, the operators and functions shown below as operating on
12294 <type>inet
</type> also work on
<type>cidr
</type> values. (Where there are
12295 separate functions for
<type>inet
</type> and
<type>cidr
</type>, it is
12296 because the behavior should be different for the two cases.)
12297 Also, it is permitted to cast an
<type>inet
</type> value
12298 to
<type>cidr
</type>. When this is done, any bits to the right of the
12299 netmask are silently zeroed to create a valid
<type>cidr
</type> value.
12302 <table id=
"cidr-inet-operators-table">
12303 <title>IP Address Operators
</title>
12307 <entry role=
"func_table_entry"><para role=
"func_signature">
12321 <entry role=
"func_table_entry"><para role=
"func_signature">
12322 <type>inet
</type> <literal><<</literal> <type>inet
</type>
12323 <returnvalue>boolean
</returnvalue>
12326 Is subnet strictly contained by subnet?
12327 This operator, and the next four, test for subnet inclusion. They
12328 consider only the network parts of the two addresses (ignoring any
12329 bits to the right of the netmasks) and determine whether one network
12330 is identical to or a subnet of the other.
12333 <literal>inet '
192.168.1.5'
<< inet '
192.168.1/
24'
</literal>
12334 <returnvalue>t
</returnvalue>
12337 <literal>inet '
192.168.0.5'
<< inet '
192.168.1/
24'
</literal>
12338 <returnvalue>f
</returnvalue>
12341 <literal>inet '
192.168.1/
24'
<< inet '
192.168.1/
24'
</literal>
12342 <returnvalue>f
</returnvalue>
12347 <entry role=
"func_table_entry"><para role=
"func_signature">
12348 <type>inet
</type> <literal><<=
</literal> <type>inet
</type>
12349 <returnvalue>boolean
</returnvalue>
12352 Is subnet contained by or equal to subnet?
12355 <literal>inet '
192.168.1/
24'
<<= inet '
192.168.1/
24'
</literal>
12356 <returnvalue>t
</returnvalue>
12361 <entry role=
"func_table_entry"><para role=
"func_signature">
12362 <type>inet
</type> <literal>>></literal> <type>inet
</type>
12363 <returnvalue>boolean
</returnvalue>
12366 Does subnet strictly contain subnet?
12369 <literal>inet '
192.168.1/
24'
>> inet '
192.168.1.5'
</literal>
12370 <returnvalue>t
</returnvalue>
12375 <entry role=
"func_table_entry"><para role=
"func_signature">
12376 <type>inet
</type> <literal>>>=
</literal> <type>inet
</type>
12377 <returnvalue>boolean
</returnvalue>
12380 Does subnet contain or equal subnet?
12383 <literal>inet '
192.168.1/
24'
>>= inet '
192.168.1/
24'
</literal>
12384 <returnvalue>t
</returnvalue>
12389 <entry role=
"func_table_entry"><para role=
"func_signature">
12390 <type>inet
</type> <literal>&&</literal> <type>inet
</type>
12391 <returnvalue>boolean
</returnvalue>
12394 Does either subnet contain or equal the other?
12397 <literal>inet '
192.168.1/
24'
&& inet '
192.168.1.80/
28'
</literal>
12398 <returnvalue>t
</returnvalue>
12401 <literal>inet '
192.168.1/
24'
&& inet '
192.168.2.0/
28'
</literal>
12402 <returnvalue>f
</returnvalue>
12407 <entry role=
"func_table_entry"><para role=
"func_signature">
12408 <literal>~
</literal> <type>inet
</type>
12409 <returnvalue>inet
</returnvalue>
12412 Computes bitwise NOT.
12415 <literal>~ inet '
192.168.1.6'
</literal>
12416 <returnvalue>63.87.254.249</returnvalue>
12421 <entry role=
"func_table_entry"><para role=
"func_signature">
12422 <type>inet
</type> <literal>&</literal> <type>inet
</type>
12423 <returnvalue>inet
</returnvalue>
12426 Computes bitwise AND.
12429 <literal>inet '
192.168.1.6'
& inet '
0.0.0.255'
</literal>
12430 <returnvalue>0.0.0.6</returnvalue>
12435 <entry role=
"func_table_entry"><para role=
"func_signature">
12436 <type>inet
</type> <literal>|
</literal> <type>inet
</type>
12437 <returnvalue>inet
</returnvalue>
12440 Computes bitwise OR.
12443 <literal>inet '
192.168.1.6' | inet '
0.0.0.255'
</literal>
12444 <returnvalue>192.168.1.255</returnvalue>
12449 <entry role=
"func_table_entry"><para role=
"func_signature">
12450 <type>inet
</type> <literal>+
</literal> <type>bigint
</type>
12451 <returnvalue>inet
</returnvalue>
12454 Adds an offset to an address.
12457 <literal>inet '
192.168.1.6' +
25</literal>
12458 <returnvalue>192.168.1.31</returnvalue>
12463 <entry role=
"func_table_entry"><para role=
"func_signature">
12464 <type>bigint
</type> <literal>+
</literal> <type>inet
</type>
12465 <returnvalue>inet
</returnvalue>
12468 Adds an offset to an address.
12471 <literal>200 + inet '::ffff:fff0:
1'
</literal>
12472 <returnvalue>::ffff:
255.240.0.201</returnvalue>
12477 <entry role=
"func_table_entry"><para role=
"func_signature">
12478 <type>inet
</type> <literal>-
</literal> <type>bigint
</type>
12479 <returnvalue>inet
</returnvalue>
12482 Subtracts an offset from an address.
12485 <literal>inet '
192.168.1.43' -
36</literal>
12486 <returnvalue>192.168.1.7</returnvalue>
12491 <entry role=
"func_table_entry"><para role=
"func_signature">
12492 <type>inet
</type> <literal>-
</literal> <type>inet
</type>
12493 <returnvalue>bigint
</returnvalue>
12496 Computes the difference of two addresses.
12499 <literal>inet '
192.168.1.43' - inet '
192.168.1.19'
</literal>
12500 <returnvalue>24</returnvalue>
12503 <literal>inet '::
1' - inet '::ffff:
1'
</literal>
12504 <returnvalue>-
4294901760</returnvalue>
12511 <table id=
"cidr-inet-functions-table">
12512 <title>IP Address Functions
</title>
12516 <entry role=
"func_table_entry"><para role=
"func_signature">
12530 <entry role=
"func_table_entry"><para role=
"func_signature">
12532 <primary>abbrev
</primary>
12534 <function>abbrev
</function> (
<type>inet
</type> )
12535 <returnvalue>text
</returnvalue>
12538 Creates an abbreviated display format as text.
12539 (The result is the same as the
<type>inet
</type> output function
12540 produces; it is
<quote>abbreviated
</quote> only in comparison to the
12541 result of an explicit cast to
<type>text
</type>, which for historical
12542 reasons will never suppress the netmask part.)
12545 <literal>abbrev(inet '
10.1.0.0/
32')
</literal>
12546 <returnvalue>10.1.0.0</returnvalue>
12551 <entry role=
"func_table_entry"><para role=
"func_signature">
12552 <function>abbrev
</function> (
<type>cidr
</type> )
12553 <returnvalue>text
</returnvalue>
12556 Creates an abbreviated display format as text.
12557 (The abbreviation consists of dropping all-zero octets to the right
12558 of the netmask; more examples are in
12559 <xref linkend=
"datatype-net-cidr-table"/>.)
12562 <literal>abbrev(cidr '
10.1.0.0/
16')
</literal>
12563 <returnvalue>10.1/
16</returnvalue>
12568 <entry role=
"func_table_entry"><para role=
"func_signature">
12570 <primary>broadcast
</primary>
12572 <function>broadcast
</function> (
<type>inet
</type> )
12573 <returnvalue>inet
</returnvalue>
12576 Computes the broadcast address for the address's network.
12579 <literal>broadcast(inet '
192.168.1.5/
24')
</literal>
12580 <returnvalue>192.168.1.255/
24</returnvalue>
12585 <entry role=
"func_table_entry"><para role=
"func_signature">
12587 <primary>family
</primary>
12589 <function>family
</function> (
<type>inet
</type> )
12590 <returnvalue>integer
</returnvalue>
12593 Returns the address's family:
<literal>4</literal> for IPv4,
12594 <literal>6</literal> for IPv6.
12597 <literal>family(inet '::
1')
</literal>
12598 <returnvalue>6</returnvalue>
12603 <entry role=
"func_table_entry"><para role=
"func_signature">
12605 <primary>host
</primary>
12607 <function>host
</function> (
<type>inet
</type> )
12608 <returnvalue>text
</returnvalue>
12611 Returns the IP address as text, ignoring the netmask.
12614 <literal>host(inet '
192.168.1.0/
24')
</literal>
12615 <returnvalue>192.168.1.0</returnvalue>
12620 <entry role=
"func_table_entry"><para role=
"func_signature">
12622 <primary>hostmask
</primary>
12624 <function>hostmask
</function> (
<type>inet
</type> )
12625 <returnvalue>inet
</returnvalue>
12628 Computes the host mask for the address's network.
12631 <literal>hostmask(inet '
192.168.23.20/
30')
</literal>
12632 <returnvalue>0.0.0.3</returnvalue>
12637 <entry role=
"func_table_entry"><para role=
"func_signature">
12639 <primary>inet_merge
</primary>
12641 <function>inet_merge
</function> (
<type>inet
</type>,
<type>inet
</type> )
12642 <returnvalue>cidr
</returnvalue>
12645 Computes the smallest network that includes both of the given networks.
12648 <literal>inet_merge(inet '
192.168.1.5/
24', inet '
192.168.2.5/
24')
</literal>
12649 <returnvalue>192.168.0.0/
22</returnvalue>
12654 <entry role=
"func_table_entry"><para role=
"func_signature">
12656 <primary>inet_same_family
</primary>
12658 <function>inet_same_family
</function> (
<type>inet
</type>,
<type>inet
</type> )
12659 <returnvalue>boolean
</returnvalue>
12662 Tests whether the addresses belong to the same IP family.
12665 <literal>inet_same_family(inet '
192.168.1.5/
24', inet '::
1')
</literal>
12666 <returnvalue>f
</returnvalue>
12671 <entry role=
"func_table_entry"><para role=
"func_signature">
12673 <primary>masklen
</primary>
12675 <function>masklen
</function> (
<type>inet
</type> )
12676 <returnvalue>integer
</returnvalue>
12679 Returns the netmask length in bits.
12682 <literal>masklen(inet '
192.168.1.5/
24')
</literal>
12683 <returnvalue>24</returnvalue>
12688 <entry role=
"func_table_entry"><para role=
"func_signature">
12690 <primary>netmask
</primary>
12692 <function>netmask
</function> (
<type>inet
</type> )
12693 <returnvalue>inet
</returnvalue>
12696 Computes the network mask for the address's network.
12699 <literal>netmask(inet '
192.168.1.5/
24')
</literal>
12700 <returnvalue>255.255.255.0</returnvalue>
12705 <entry role=
"func_table_entry"><para role=
"func_signature">
12707 <primary>network
</primary>
12709 <function>network
</function> (
<type>inet
</type> )
12710 <returnvalue>cidr
</returnvalue>
12713 Returns the network part of the address, zeroing out
12714 whatever is to the right of the netmask.
12715 (This is equivalent to casting the value to
<type>cidr
</type>.)
12718 <literal>network(inet '
192.168.1.5/
24')
</literal>
12719 <returnvalue>192.168.1.0/
24</returnvalue>
12724 <entry role=
"func_table_entry"><para role=
"func_signature">
12726 <primary>set_masklen
</primary>
12728 <function>set_masklen
</function> (
<type>inet
</type>,
<type>integer
</type> )
12729 <returnvalue>inet
</returnvalue>
12732 Sets the netmask length for an
<type>inet
</type> value.
12733 The address part does not change.
12736 <literal>set_masklen(inet '
192.168.1.5/
24',
16)
</literal>
12737 <returnvalue>192.168.1.5/
16</returnvalue>
12742 <entry role=
"func_table_entry"><para role=
"func_signature">
12743 <function>set_masklen
</function> (
<type>cidr
</type>,
<type>integer
</type> )
12744 <returnvalue>cidr
</returnvalue>
12747 Sets the netmask length for a
<type>cidr
</type> value.
12748 Address bits to the right of the new netmask are set to zero.
12751 <literal>set_masklen(cidr '
192.168.1.0/
24',
16)
</literal>
12752 <returnvalue>192.168.0.0/
16</returnvalue>
12757 <entry role=
"func_table_entry"><para role=
"func_signature">
12759 <primary>text
</primary>
12761 <function>text
</function> (
<type>inet
</type> )
12762 <returnvalue>text
</returnvalue>
12765 Returns the unabbreviated IP address and netmask length as text.
12766 (This has the same result as an explicit cast to
<type>text
</type>.)
12769 <literal>text(inet '
192.168.1.5')
</literal>
12770 <returnvalue>192.168.1.5/
32</returnvalue>
12779 The
<function>abbrev
</function>,
<function>host
</function>,
12780 and
<function>text
</function> functions are primarily intended to offer
12781 alternative display formats for IP addresses.
12786 The MAC address types,
<type>macaddr
</type> and
<type>macaddr8
</type>,
12787 support the usual comparison operators shown in
12788 <xref linkend=
"functions-comparison-op-table"/>
12789 as well as the specialized functions shown in
12790 <xref linkend=
"macaddr-functions-table"/>.
12791 In addition, they support the bitwise logical operators
12792 <literal>~
</literal>,
<literal>&</literal> and
<literal>|
</literal>
12793 (NOT, AND and OR), just as shown above for IP addresses.
12796 <table id=
"macaddr-functions-table">
12797 <title>MAC Address Functions
</title>
12801 <entry role=
"func_table_entry"><para role=
"func_signature">
12815 <entry role=
"func_table_entry"><para role=
"func_signature">
12817 <primary>trunc
</primary>
12819 <function>trunc
</function> (
<type>macaddr
</type> )
12820 <returnvalue>macaddr
</returnvalue>
12823 Sets the last
3 bytes of the address to zero. The remaining prefix
12824 can be associated with a particular manufacturer (using data not
12825 included in
<productname>PostgreSQL
</productname>).
12828 <literal>trunc(macaddr '
12:
34:
56:
78:
90:ab')
</literal>
12829 <returnvalue>12:
34:
56:
00:
00:
00</returnvalue>
12834 <entry role=
"func_table_entry"><para role=
"func_signature">
12835 <function>trunc
</function> (
<type>macaddr8
</type> )
12836 <returnvalue>macaddr8
</returnvalue>
12839 Sets the last
5 bytes of the address to zero. The remaining prefix
12840 can be associated with a particular manufacturer (using data not
12841 included in
<productname>PostgreSQL
</productname>).
12844 <literal>trunc(macaddr8 '
12:
34:
56:
78:
90:ab:cd:ef')
</literal>
12845 <returnvalue>12:
34:
56:
00:
00:
00:
00:
00</returnvalue>
12850 <entry role=
"func_table_entry"><para role=
"func_signature">
12852 <primary>macaddr8_set7bit
</primary>
12854 <function>macaddr8_set7bit
</function> (
<type>macaddr8
</type> )
12855 <returnvalue>macaddr8
</returnvalue>
12858 Sets the
7th bit of the address to one, creating what is known as
12859 modified EUI-
64, for inclusion in an IPv6 address.
12862 <literal>macaddr8_set7bit(macaddr8 '
00:
34:
56:ab:cd:ef')
</literal>
12863 <returnvalue>02:
34:
56:ff:fe:ab:cd:ef
</returnvalue>
12873 <sect1 id=
"functions-textsearch">
12874 <title>Text Search Functions and Operators
</title>
12876 <indexterm zone=
"datatype-textsearch">
12877 <primary>full text search
</primary>
12878 <secondary>functions and operators
</secondary>
12881 <indexterm zone=
"datatype-textsearch">
12882 <primary>text search
</primary>
12883 <secondary>functions and operators
</secondary>
12887 <xref linkend=
"textsearch-operators-table"/>,
12888 <xref linkend=
"textsearch-functions-table"/> and
12889 <xref linkend=
"textsearch-functions-debug-table"/>
12890 summarize the functions and operators that are provided
12891 for full text searching. See
<xref linkend=
"textsearch"/> for a detailed
12892 explanation of
<productname>PostgreSQL
</productname>'s text search
12896 <table id=
"textsearch-operators-table">
12897 <title>Text Search Operators
</title>
12901 <entry role=
"func_table_entry"><para role=
"func_signature">
12915 <entry role=
"func_table_entry"><para role=
"func_signature">
12916 <type>tsvector
</type> <literal>@@
</literal> <type>tsquery
</type>
12917 <returnvalue>boolean
</returnvalue>
12919 <para role=
"func_signature">
12920 <type>tsquery
</type> <literal>@@
</literal> <type>tsvector
</type>
12921 <returnvalue>boolean
</returnvalue>
12924 Does
<type>tsvector
</type> match
<type>tsquery
</type>?
12925 (The arguments can be given in either order.)
12928 <literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat
& rat')
</literal>
12929 <returnvalue>t
</returnvalue>
12934 <entry role=
"func_table_entry"><para role=
"func_signature">
12935 <type>text
</type> <literal>@@
</literal> <type>tsquery
</type>
12936 <returnvalue>boolean
</returnvalue>
12939 Does text string, after implicit invocation
12940 of
<function>to_tsvector()
</function>, match
<type>tsquery
</type>?
12943 <literal>'fat cats ate rats' @@ to_tsquery('cat
& rat')
</literal>
12944 <returnvalue>t
</returnvalue>
12949 <entry role=
"func_table_entry"><para role=
"func_signature">
12950 <type>tsvector
</type> <literal>@@@
</literal> <type>tsquery
</type>
12951 <returnvalue>boolean
</returnvalue>
12953 <para role=
"func_signature">
12954 <type>tsquery
</type> <literal>@@@
</literal> <type>tsvector
</type>
12955 <returnvalue>boolean
</returnvalue>
12958 This is a deprecated synonym for
<literal>@@
</literal>.
12961 <literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat
& rat')
</literal>
12962 <returnvalue>t
</returnvalue>
12967 <entry role=
"func_table_entry"><para role=
"func_signature">
12968 <type>tsvector
</type> <literal>||
</literal> <type>tsvector
</type>
12969 <returnvalue>tsvector
</returnvalue>
12972 Concatenates two
<type>tsvector
</type>s. If both inputs contain
12973 lexeme positions, the second input's positions are adjusted
12977 <literal>'a:
1 b:
2'::tsvector || 'c:
1 d:
2 b:
3'::tsvector
</literal>
12978 <returnvalue>'a':
1 'b':
2,
5 'c':
3 'd':
4</returnvalue>
12983 <entry role=
"func_table_entry"><para role=
"func_signature">
12984 <type>tsquery
</type> <literal>&&</literal> <type>tsquery
</type>
12985 <returnvalue>tsquery
</returnvalue>
12988 ANDs two
<type>tsquery
</type>s together, producing a query that
12989 matches documents that match both input queries.
12992 <literal>'fat | rat'::tsquery
&& 'cat'::tsquery
</literal>
12993 <returnvalue>( 'fat' | 'rat' )
& 'cat'
</returnvalue>
12998 <entry role=
"func_table_entry"><para role=
"func_signature">
12999 <type>tsquery
</type> <literal>||
</literal> <type>tsquery
</type>
13000 <returnvalue>tsquery
</returnvalue>
13003 ORs two
<type>tsquery
</type>s together, producing a query that
13004 matches documents that match either input query.
13007 <literal>'fat | rat'::tsquery || 'cat'::tsquery
</literal>
13008 <returnvalue>'fat' | 'rat' | 'cat'
</returnvalue>
13013 <entry role=
"func_table_entry"><para role=
"func_signature">
13014 <literal>!!
</literal> <type>tsquery
</type>
13015 <returnvalue>tsquery
</returnvalue>
13018 Negates a
<type>tsquery
</type>, producing a query that matches
13019 documents that do not match the input query.
13022 <literal>!! 'cat'::tsquery
</literal>
13023 <returnvalue>!'cat'
</returnvalue>
13028 <entry role=
"func_table_entry"><para role=
"func_signature">
13029 <type>tsquery
</type> <literal><-
></literal> <type>tsquery
</type>
13030 <returnvalue>tsquery
</returnvalue>
13033 Constructs a phrase query, which matches if the two input queries
13034 match at successive lexemes.
13037 <literal>to_tsquery('fat')
<-
> to_tsquery('rat')
</literal>
13038 <returnvalue>'fat'
<-
> 'rat'
</returnvalue>
13043 <entry role=
"func_table_entry"><para role=
"func_signature">
13044 <type>tsquery
</type> <literal>@
></literal> <type>tsquery
</type>
13045 <returnvalue>boolean
</returnvalue>
13048 Does first
<type>tsquery
</type> contain the second? (This considers
13049 only whether all the lexemes appearing in one query appear in the
13050 other, ignoring the combining operators.)
13053 <literal>'cat'::tsquery @
> 'cat
& rat'::tsquery
</literal>
13054 <returnvalue>f
</returnvalue>
13059 <entry role=
"func_table_entry"><para role=
"func_signature">
13060 <type>tsquery
</type> <literal><@
</literal> <type>tsquery
</type>
13061 <returnvalue>boolean
</returnvalue>
13064 Is first
<type>tsquery
</type> contained in the second? (This
13065 considers only whether all the lexemes appearing in one query appear
13066 in the other, ignoring the combining operators.)
13069 <literal>'cat'::tsquery
<@ 'cat
& rat'::tsquery
</literal>
13070 <returnvalue>t
</returnvalue>
13073 <literal>'cat'::tsquery
<@ '!cat
& rat'::tsquery
</literal>
13074 <returnvalue>t
</returnvalue>
13082 In addition to these specialized operators, the usual comparison
13083 operators shown in
<xref linkend=
"functions-comparison-op-table"/> are
13084 available for types
<type>tsvector
</type> and
<type>tsquery
</type>.
13086 useful for text searching but allow, for example, unique indexes to be
13087 built on columns of these types.
13090 <table id=
"textsearch-functions-table">
13091 <title>Text Search Functions
</title>
13095 <entry role=
"func_table_entry"><para role=
"func_signature">
13109 <entry role=
"func_table_entry"><para role=
"func_signature">
13111 <primary>array_to_tsvector
</primary>
13113 <function>array_to_tsvector
</function> (
<type>text[]
</type> )
13114 <returnvalue>tsvector
</returnvalue>
13117 Converts an array of text strings to a
<type>tsvector
</type>.
13118 The given strings are used as lexemes as-is, without further
13119 processing. Array elements must not be empty strings
13120 or
<literal>NULL
</literal>.
13123 <literal>array_to_tsvector('{fat,cat,rat}'::text[])
</literal>
13124 <returnvalue>'cat' 'fat' 'rat'
</returnvalue>
13129 <entry role=
"func_table_entry"><para role=
"func_signature">
13131 <primary>get_current_ts_config
</primary>
13133 <function>get_current_ts_config
</function> ( )
13134 <returnvalue>regconfig
</returnvalue>
13137 Returns the OID of the current default text search configuration
13138 (as set by
<xref linkend=
"guc-default-text-search-config"/>).
13141 <literal>get_current_ts_config()
</literal>
13142 <returnvalue>english
</returnvalue>
13147 <entry role=
"func_table_entry"><para role=
"func_signature">
13149 <primary>length
</primary>
13151 <function>length
</function> (
<type>tsvector
</type> )
13152 <returnvalue>integer
</returnvalue>
13155 Returns the number of lexemes in the
<type>tsvector
</type>.
13158 <literal>length('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13159 <returnvalue>3</returnvalue>
13164 <entry role=
"func_table_entry"><para role=
"func_signature">
13166 <primary>numnode
</primary>
13168 <function>numnode
</function> (
<type>tsquery
</type> )
13169 <returnvalue>integer
</returnvalue>
13172 Returns the number of lexemes plus operators in
13173 the
<type>tsquery
</type>.
13176 <literal>numnode('(fat
& rat) | cat'::tsquery)
</literal>
13177 <returnvalue>5</returnvalue>
13182 <entry role=
"func_table_entry"><para role=
"func_signature">
13184 <primary>plainto_tsquery
</primary>
13186 <function>plainto_tsquery
</function> (
13187 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13188 <parameter>query
</parameter> <type>text
</type> )
13189 <returnvalue>tsquery
</returnvalue>
13192 Converts text to a
<type>tsquery
</type>, normalizing words according to
13193 the specified or default configuration. Any punctuation in the string
13194 is ignored (it does not determine query operators). The resulting
13195 query matches documents containing all non-stopwords in the text.
13198 <literal>plainto_tsquery('english', 'The Fat Rats')
</literal>
13199 <returnvalue>'fat'
& 'rat'
</returnvalue>
13204 <entry role=
"func_table_entry"><para role=
"func_signature">
13206 <primary>phraseto_tsquery
</primary>
13208 <function>phraseto_tsquery
</function> (
13209 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13210 <parameter>query
</parameter> <type>text
</type> )
13211 <returnvalue>tsquery
</returnvalue>
13214 Converts text to a
<type>tsquery
</type>, normalizing words according to
13215 the specified or default configuration. Any punctuation in the string
13216 is ignored (it does not determine query operators). The resulting
13217 query matches phrases containing all non-stopwords in the text.
13220 <literal>phraseto_tsquery('english', 'The Fat Rats')
</literal>
13221 <returnvalue>'fat'
<-
> 'rat'
</returnvalue>
13224 <literal>phraseto_tsquery('english', 'The Cat and Rats')
</literal>
13225 <returnvalue>'cat'
<2> 'rat'
</returnvalue>
13230 <entry role=
"func_table_entry"><para role=
"func_signature">
13232 <primary>websearch_to_tsquery
</primary>
13234 <function>websearch_to_tsquery
</function> (
13235 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13236 <parameter>query
</parameter> <type>text
</type> )
13237 <returnvalue>tsquery
</returnvalue>
13240 Converts text to a
<type>tsquery
</type>, normalizing words according
13241 to the specified or default configuration. Quoted word sequences are
13242 converted to phrase tests. The word
<quote>or
</quote> is understood
13243 as producing an OR operator, and a dash produces a NOT operator;
13244 other punctuation is ignored.
13245 This approximates the behavior of some common web search tools.
13248 <literal>websearch_to_tsquery('english', '
"fat rat" or cat dog')
</literal>
13249 <returnvalue>'fat'
<-
> 'rat' | 'cat'
& 'dog'
</returnvalue>
13254 <entry role=
"func_table_entry"><para role=
"func_signature">
13256 <primary>querytree
</primary>
13258 <function>querytree
</function> (
<type>tsquery
</type> )
13259 <returnvalue>text
</returnvalue>
13262 Produces a representation of the indexable portion of
13263 a
<type>tsquery
</type>. A result that is empty or
13264 just
<literal>T
</literal> indicates a non-indexable query.
13267 <literal>querytree('foo
& ! bar'::tsquery)
</literal>
13268 <returnvalue>'foo'
</returnvalue>
13273 <entry role=
"func_table_entry"><para role=
"func_signature">
13275 <primary>setweight
</primary>
13277 <function>setweight
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weight
</parameter> <type>"char"</type> )
13278 <returnvalue>tsvector
</returnvalue>
13281 Assigns the specified
<parameter>weight
</parameter> to each element
13282 of the
<parameter>vector
</parameter>.
13285 <literal>setweight('fat:
2,
4 cat:
3 rat:
5B'::tsvector, 'A')
</literal>
13286 <returnvalue>'cat':
3A 'fat':
2A,
4A 'rat':
5A
</returnvalue>
13291 <entry role=
"func_table_entry"><para role=
"func_signature">
13293 <primary>setweight
</primary>
13294 <secondary>setweight for specific lexeme(s)
</secondary>
13296 <function>setweight
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weight
</parameter> <type>"char"</type>,
<parameter>lexemes
</parameter> <type>text[]
</type> )
13297 <returnvalue>tsvector
</returnvalue>
13300 Assigns the specified
<parameter>weight
</parameter> to elements
13301 of the
<parameter>vector
</parameter> that are listed
13302 in
<parameter>lexemes
</parameter>.
13303 The strings in
<parameter>lexemes
</parameter> are taken as lexemes
13304 as-is, without further processing. Strings that do not match any
13305 lexeme in
<parameter>vector
</parameter> are ignored.
13308 <literal>setweight('fat:
2,
4 cat:
3 rat:
5,
6B'::tsvector, 'A', '{cat,rat}')
</literal>
13309 <returnvalue>'cat':
3A 'fat':
2,
4 'rat':
5A,
6A
</returnvalue>
13314 <entry role=
"func_table_entry"><para role=
"func_signature">
13316 <primary>strip
</primary>
13318 <function>strip
</function> (
<type>tsvector
</type> )
13319 <returnvalue>tsvector
</returnvalue>
13322 Removes positions and weights from the
<type>tsvector
</type>.
13325 <literal>strip('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13326 <returnvalue>'cat' 'fat' 'rat'
</returnvalue>
13331 <entry role=
"func_table_entry"><para role=
"func_signature">
13333 <primary>to_tsquery
</primary>
13335 <function>to_tsquery
</function> (
13336 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13337 <parameter>query
</parameter> <type>text
</type> )
13338 <returnvalue>tsquery
</returnvalue>
13341 Converts text to a
<type>tsquery
</type>, normalizing words according to
13342 the specified or default configuration. The words must be combined
13343 by valid
<type>tsquery
</type> operators.
13346 <literal>to_tsquery('english', 'The
& Fat
& Rats')
</literal>
13347 <returnvalue>'fat'
& 'rat'
</returnvalue>
13352 <entry role=
"func_table_entry"><para role=
"func_signature">
13354 <primary>to_tsvector
</primary>
13356 <function>to_tsvector
</function> (
13357 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13358 <parameter>document
</parameter> <type>text
</type> )
13359 <returnvalue>tsvector
</returnvalue>
13362 Converts text to a
<type>tsvector
</type>, normalizing words according
13363 to the specified or default configuration. Position information is
13364 included in the result.
13367 <literal>to_tsvector('english', 'The Fat Rats')
</literal>
13368 <returnvalue>'fat':
2 'rat':
3</returnvalue>
13373 <entry role=
"func_table_entry"><para role=
"func_signature">
13374 <function>to_tsvector
</function> (
13375 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13376 <parameter>document
</parameter> <type>json
</type> )
13377 <returnvalue>tsvector
</returnvalue>
13379 <para role=
"func_signature">
13380 <function>to_tsvector
</function> (
13381 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13382 <parameter>document
</parameter> <type>jsonb
</type> )
13383 <returnvalue>tsvector
</returnvalue>
13386 Converts each string value in the JSON document to
13387 a
<type>tsvector
</type>, normalizing words according to the specified
13388 or default configuration. The results are then concatenated in
13389 document order to produce the output. Position information is
13390 generated as though one stopword exists between each pair of string
13391 values. (Beware that
<quote>document order
</quote> of the fields of a
13392 JSON object is implementation-dependent when the input
13393 is
<type>jsonb
</type>; observe the difference in the examples.)
13396 <literal>to_tsvector('english', '{
"aa":
"The Fat Rats",
"b":
"dog"}'::json)
</literal>
13397 <returnvalue>'dog':
5 'fat':
2 'rat':
3</returnvalue>
13400 <literal>to_tsvector('english', '{
"aa":
"The Fat Rats",
"b":
"dog"}'::jsonb)
</literal>
13401 <returnvalue>'dog':
1 'fat':
4 'rat':
5</returnvalue>
13406 <entry role=
"func_table_entry"><para role=
"func_signature">
13408 <primary>json_to_tsvector
</primary>
13410 <function>json_to_tsvector
</function> (
13411 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13412 <parameter>document
</parameter> <type>json
</type>,
13413 <parameter>filter
</parameter> <type>jsonb
</type> )
13414 <returnvalue>tsvector
</returnvalue>
13416 <para role=
"func_signature">
13418 <primary>jsonb_to_tsvector
</primary>
13420 <function>jsonb_to_tsvector
</function> (
13421 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13422 <parameter>document
</parameter> <type>jsonb
</type>,
13423 <parameter>filter
</parameter> <type>jsonb
</type> )
13424 <returnvalue>tsvector
</returnvalue>
13427 Selects each item in the JSON document that is requested by
13428 the
<parameter>filter
</parameter> and converts each one to
13429 a
<type>tsvector
</type>, normalizing words according to the specified
13430 or default configuration. The results are then concatenated in
13431 document order to produce the output. Position information is
13432 generated as though one stopword exists between each pair of selected
13433 items. (Beware that
<quote>document order
</quote> of the fields of a
13434 JSON object is implementation-dependent when the input
13435 is
<type>jsonb
</type>.)
13436 The
<parameter>filter
</parameter> must be a
<type>jsonb
</type>
13437 array containing zero or more of these keywords:
13438 <literal>"string"</literal> (to include all string values),
13439 <literal>"numeric"</literal> (to include all numeric values),
13440 <literal>"boolean"</literal> (to include all boolean values),
13441 <literal>"key"</literal> (to include all keys), or
13442 <literal>"all"</literal> (to include all the above).
13443 As a special case, the
<parameter>filter
</parameter> can also be a
13444 simple JSON value that is one of these keywords.
13447 <literal>json_to_tsvector('english', '{
"a":
"The Fat Rats",
"b":
123}'::json, '[
"string",
"numeric"]')
</literal>
13448 <returnvalue>'
123':
5 'fat':
2 'rat':
3</returnvalue>
13451 <literal>json_to_tsvector('english', '{
"cat":
"The Fat Rats",
"dog":
123}'::json, '
"all"')
</literal>
13452 <returnvalue>'
123':
9 'cat':
1 'dog':
7 'fat':
4 'rat':
5</returnvalue>
13457 <entry role=
"func_table_entry"><para role=
"func_signature">
13459 <primary>ts_delete
</primary>
13461 <function>ts_delete
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>lexeme
</parameter> <type>text
</type> )
13462 <returnvalue>tsvector
</returnvalue>
13465 Removes any occurrence of the given
<parameter>lexeme
</parameter>
13466 from the
<parameter>vector
</parameter>.
13467 The
<parameter>lexeme
</parameter> string is treated as a lexeme as-is,
13468 without further processing.
13471 <literal>ts_delete('fat:
2,
4 cat:
3 rat:
5A'::tsvector, 'fat')
</literal>
13472 <returnvalue>'cat':
3 'rat':
5A
</returnvalue>
13477 <entry role=
"func_table_entry"><para role=
"func_signature">
13478 <function>ts_delete
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>lexemes
</parameter> <type>text[]
</type> )
13479 <returnvalue>tsvector
</returnvalue>
13482 Removes any occurrences of the lexemes
13483 in
<parameter>lexemes
</parameter>
13484 from the
<parameter>vector
</parameter>.
13485 The strings in
<parameter>lexemes
</parameter> are taken as lexemes
13486 as-is, without further processing. Strings that do not match any
13487 lexeme in
<parameter>vector
</parameter> are ignored.
13490 <literal>ts_delete('fat:
2,
4 cat:
3 rat:
5A'::tsvector, ARRAY['fat','rat'])
</literal>
13491 <returnvalue>'cat':
3</returnvalue>
13496 <entry role=
"func_table_entry"><para role=
"func_signature">
13498 <primary>ts_filter
</primary>
13500 <function>ts_filter
</function> (
<parameter>vector
</parameter> <type>tsvector
</type>,
<parameter>weights
</parameter> <type>"char"[]
</type> )
13501 <returnvalue>tsvector
</returnvalue>
13504 Selects only elements with the given
<parameter>weights
</parameter>
13505 from the
<parameter>vector
</parameter>.
13508 <literal>ts_filter('fat:
2,
4 cat:
3b,
7c rat:
5A'::tsvector, '{a,b}')
</literal>
13509 <returnvalue>'cat':
3B 'rat':
5A
</returnvalue>
13514 <entry role=
"func_table_entry"><para role=
"func_signature">
13516 <primary>ts_headline
</primary>
13518 <function>ts_headline
</function> (
13519 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13520 <parameter>document
</parameter> <type>text
</type>,
13521 <parameter>query
</parameter> <type>tsquery
</type>
13522 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13523 <returnvalue>text
</returnvalue>
13526 Displays, in an abbreviated form, the match(es) for
13527 the
<parameter>query
</parameter> in
13528 the
<parameter>document
</parameter>, which must be raw text not
13529 a
<type>tsvector
</type>. Words in the document are normalized
13530 according to the specified or default configuration before matching to
13531 the query. Use of this function is discussed in
13532 <xref linkend=
"textsearch-headline"/>, which also describes the
13533 available
<parameter>options
</parameter>.
13536 <literal>ts_headline('The fat cat ate the rat.', 'cat')
</literal>
13537 <returnvalue>The fat
<b
>cat
</b
> ate the rat.
</returnvalue>
13542 <entry role=
"func_table_entry"><para role=
"func_signature">
13543 <function>ts_headline
</function> (
13544 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13545 <parameter>document
</parameter> <type>json
</type>,
13546 <parameter>query
</parameter> <type>tsquery
</type>
13547 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13548 <returnvalue>text
</returnvalue>
13550 <para role=
"func_signature">
13551 <function>ts_headline
</function> (
13552 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13553 <parameter>document
</parameter> <type>jsonb
</type>,
13554 <parameter>query
</parameter> <type>tsquery
</type>
13555 <optional>,
<parameter>options
</parameter> <type>text
</type> </optional> )
13556 <returnvalue>text
</returnvalue>
13559 Displays, in an abbreviated form, match(es) for
13560 the
<parameter>query
</parameter> that occur in string values
13561 within the JSON
<parameter>document
</parameter>.
13562 See
<xref linkend=
"textsearch-headline"/> for more details.
13565 <literal>ts_headline('{
"cat":
"raining cats and dogs"}'::jsonb, 'cat')
</literal>
13566 <returnvalue>{
"cat":
"raining <b>cats</b> and dogs"}
</returnvalue>
13571 <entry role=
"func_table_entry"><para role=
"func_signature">
13573 <primary>ts_rank
</primary>
13575 <function>ts_rank
</function> (
13576 <optional> <parameter>weights
</parameter> <type>real[]
</type>,
</optional>
13577 <parameter>vector
</parameter> <type>tsvector
</type>,
13578 <parameter>query
</parameter> <type>tsquery
</type>
13579 <optional>,
<parameter>normalization
</parameter> <type>integer
</type> </optional> )
13580 <returnvalue>real
</returnvalue>
13583 Computes a score showing how well
13584 the
<parameter>vector
</parameter> matches
13585 the
<parameter>query
</parameter>. See
13586 <xref linkend=
"textsearch-ranking"/> for details.
13589 <literal>ts_rank(to_tsvector('raining cats and dogs'), 'cat')
</literal>
13590 <returnvalue>0.06079271</returnvalue>
13595 <entry role=
"func_table_entry"><para role=
"func_signature">
13597 <primary>ts_rank_cd
</primary>
13599 <function>ts_rank_cd
</function> (
13600 <optional> <parameter>weights
</parameter> <type>real[]
</type>,
</optional>
13601 <parameter>vector
</parameter> <type>tsvector
</type>,
13602 <parameter>query
</parameter> <type>tsquery
</type>
13603 <optional>,
<parameter>normalization
</parameter> <type>integer
</type> </optional> )
13604 <returnvalue>real
</returnvalue>
13607 Computes a score showing how well
13608 the
<parameter>vector
</parameter> matches
13609 the
<parameter>query
</parameter>, using a cover density
13610 algorithm. See
<xref linkend=
"textsearch-ranking"/> for details.
13613 <literal>ts_rank_cd(to_tsvector('raining cats and dogs'), 'cat')
</literal>
13614 <returnvalue>0.1</returnvalue>
13619 <entry role=
"func_table_entry"><para role=
"func_signature">
13621 <primary>ts_rewrite
</primary>
13623 <function>ts_rewrite
</function> (
<parameter>query
</parameter> <type>tsquery
</type>,
13624 <parameter>target
</parameter> <type>tsquery
</type>,
13625 <parameter>substitute
</parameter> <type>tsquery
</type> )
13626 <returnvalue>tsquery
</returnvalue>
13629 Replaces occurrences of
<parameter>target
</parameter>
13630 with
<parameter>substitute
</parameter>
13631 within the
<parameter>query
</parameter>.
13632 See
<xref linkend=
"textsearch-query-rewriting"/> for details.
13635 <literal>ts_rewrite('a
& b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)
</literal>
13636 <returnvalue>'b'
& ( 'foo' | 'bar' )
</returnvalue>
13641 <entry role=
"func_table_entry"><para role=
"func_signature">
13642 <function>ts_rewrite
</function> (
<parameter>query
</parameter> <type>tsquery
</type>,
13643 <parameter>select
</parameter> <type>text
</type> )
13644 <returnvalue>tsquery
</returnvalue>
13647 Replaces portions of the
<parameter>query
</parameter> according to
13648 target(s) and substitute(s) obtained by executing
13649 a
<command>SELECT
</command> command.
13650 See
<xref linkend=
"textsearch-query-rewriting"/> for details.
13653 <literal>SELECT ts_rewrite('a
& b'::tsquery, 'SELECT t,s FROM aliases')
</literal>
13654 <returnvalue>'b'
& ( 'foo' | 'bar' )
</returnvalue>
13659 <entry role=
"func_table_entry"><para role=
"func_signature">
13661 <primary>tsquery_phrase
</primary>
13663 <function>tsquery_phrase
</function> (
<parameter>query1
</parameter> <type>tsquery
</type>,
<parameter>query2
</parameter> <type>tsquery
</type> )
13664 <returnvalue>tsquery
</returnvalue>
13667 Constructs a phrase query that searches
13668 for matches of
<parameter>query1
</parameter>
13669 and
<parameter>query2
</parameter> at successive lexemes (same
13670 as
<literal><-
></literal> operator).
13673 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'))
</literal>
13674 <returnvalue>'fat'
<-
> 'cat'
</returnvalue>
13679 <entry role=
"func_table_entry"><para role=
"func_signature">
13680 <function>tsquery_phrase
</function> (
<parameter>query1
</parameter> <type>tsquery
</type>,
<parameter>query2
</parameter> <type>tsquery
</type>,
<parameter>distance
</parameter> <type>integer
</type> )
13681 <returnvalue>tsquery
</returnvalue>
13684 Constructs a phrase query that searches
13685 for matches of
<parameter>query1
</parameter> and
13686 <parameter>query2
</parameter> that occur exactly
13687 <parameter>distance
</parameter> lexemes apart.
13690 <literal>tsquery_phrase(to_tsquery('fat'), to_tsquery('cat'),
10)
</literal>
13691 <returnvalue>'fat'
<10> 'cat'
</returnvalue>
13696 <entry role=
"func_table_entry"><para role=
"func_signature">
13698 <primary>tsvector_to_array
</primary>
13700 <function>tsvector_to_array
</function> (
<type>tsvector
</type> )
13701 <returnvalue>text[]
</returnvalue>
13704 Converts a
<type>tsvector
</type> to an array of lexemes.
13707 <literal>tsvector_to_array('fat:
2,
4 cat:
3 rat:
5A'::tsvector)
</literal>
13708 <returnvalue>{cat,fat,rat}
</returnvalue>
13713 <entry role=
"func_table_entry"><para role=
"func_signature">
13715 <primary>unnest
</primary>
13716 <secondary>for tsvector
</secondary>
13718 <function>unnest
</function> (
<type>tsvector
</type> )
13719 <returnvalue>setof record
</returnvalue>
13720 (
<parameter>lexeme
</parameter> <type>text
</type>,
13721 <parameter>positions
</parameter> <type>smallint[]
</type>,
13722 <parameter>weights
</parameter> <type>text
</type> )
13725 Expands a
<type>tsvector
</type> into a set of rows, one per lexeme.
13728 <literal>select * from unnest('cat:
3 fat:
2,
4 rat:
5A'::tsvector)
</literal>
13729 <returnvalue></returnvalue>
13731 lexeme | positions | weights
13732 --------+-----------+---------
13734 fat | {
2,
4} | {D,D}
13745 All the text search functions that accept an optional
<type>regconfig
</type>
13746 argument will use the configuration specified by
13747 <xref linkend=
"guc-default-text-search-config"/>
13748 when that argument is omitted.
13754 <xref linkend=
"textsearch-functions-debug-table"/>
13755 are listed separately because they are not usually used in everyday text
13756 searching operations. They are primarily helpful for development and
13757 debugging of new text search configurations.
13760 <table id=
"textsearch-functions-debug-table">
13761 <title>Text Search Debugging Functions
</title>
13765 <entry role=
"func_table_entry"><para role=
"func_signature">
13779 <entry role=
"func_table_entry"><para role=
"func_signature">
13781 <primary>ts_debug
</primary>
13783 <function>ts_debug
</function> (
13784 <optional> <parameter>config
</parameter> <type>regconfig
</type>,
</optional>
13785 <parameter>document
</parameter> <type>text
</type> )
13786 <returnvalue>setof record
</returnvalue>
13787 (
<parameter>alias
</parameter> <type>text
</type>,
13788 <parameter>description
</parameter> <type>text
</type>,
13789 <parameter>token
</parameter> <type>text
</type>,
13790 <parameter>dictionaries
</parameter> <type>regdictionary[]
</type>,
13791 <parameter>dictionary
</parameter> <type>regdictionary
</type>,
13792 <parameter>lexemes
</parameter> <type>text[]
</type> )
13795 Extracts and normalizes tokens from
13796 the
<parameter>document
</parameter> according to the specified or
13797 default text search configuration, and returns information about how
13798 each token was processed.
13799 See
<xref linkend=
"textsearch-configuration-testing"/> for details.
13802 <literal>ts_debug('english', 'The Brightest supernovaes')
</literal>
13803 <returnvalue>(asciiword,
"Word, all ASCII",The,{english_stem},english_stem,{}) ...
</returnvalue>
13808 <entry role=
"func_table_entry"><para role=
"func_signature">
13810 <primary>ts_lexize
</primary>
13812 <function>ts_lexize
</function> (
<parameter>dict
</parameter> <type>regdictionary
</type>,
<parameter>token
</parameter> <type>text
</type> )
13813 <returnvalue>text[]
</returnvalue>
13816 Returns an array of replacement lexemes if the input token is known to
13817 the dictionary, or an empty array if the token is known to the
13818 dictionary but it is a stop word, or NULL if it is not a known word.
13819 See
<xref linkend=
"textsearch-dictionary-testing"/> for details.
13822 <literal>ts_lexize('english_stem', 'stars')
</literal>
13823 <returnvalue>{star}
</returnvalue>
13828 <entry role=
"func_table_entry"><para role=
"func_signature">
13830 <primary>ts_parse
</primary>
13832 <function>ts_parse
</function> (
<parameter>parser_name
</parameter> <type>text
</type>,
13833 <parameter>document
</parameter> <type>text
</type> )
13834 <returnvalue>setof record
</returnvalue>
13835 (
<parameter>tokid
</parameter> <type>integer
</type>,
13836 <parameter>token
</parameter> <type>text
</type> )
13839 Extracts tokens from the
<parameter>document
</parameter> using the
13841 See
<xref linkend=
"textsearch-parser-testing"/> for details.
13844 <literal>ts_parse('default', 'foo - bar')
</literal>
13845 <returnvalue>(
1,foo) ...
</returnvalue>
13850 <entry role=
"func_table_entry"><para role=
"func_signature">
13851 <function>ts_parse
</function> (
<parameter>parser_oid
</parameter> <type>oid
</type>,
13852 <parameter>document
</parameter> <type>text
</type> )
13853 <returnvalue>setof record
</returnvalue>
13854 (
<parameter>tokid
</parameter> <type>integer
</type>,
13855 <parameter>token
</parameter> <type>text
</type> )
13858 Extracts tokens from the
<parameter>document
</parameter> using a
13859 parser specified by OID.
13860 See
<xref linkend=
"textsearch-parser-testing"/> for details.
13863 <literal>ts_parse(
3722, 'foo - bar')
</literal>
13864 <returnvalue>(
1,foo) ...
</returnvalue>
13869 <entry role=
"func_table_entry"><para role=
"func_signature">
13871 <primary>ts_token_type
</primary>
13873 <function>ts_token_type
</function> (
<parameter>parser_name
</parameter> <type>text
</type> )
13874 <returnvalue>setof record
</returnvalue>
13875 (
<parameter>tokid
</parameter> <type>integer
</type>,
13876 <parameter>alias
</parameter> <type>text
</type>,
13877 <parameter>description
</parameter> <type>text
</type> )
13880 Returns a table that describes each type of token the named parser can
13882 See
<xref linkend=
"textsearch-parser-testing"/> for details.
13885 <literal>ts_token_type('default')
</literal>
13886 <returnvalue>(
1,asciiword,
"Word, all ASCII") ...
</returnvalue>
13891 <entry role=
"func_table_entry"><para role=
"func_signature">
13892 <function>ts_token_type
</function> (
<parameter>parser_oid
</parameter> <type>oid
</type> )
13893 <returnvalue>setof record
</returnvalue>
13894 (
<parameter>tokid
</parameter> <type>integer
</type>,
13895 <parameter>alias
</parameter> <type>text
</type>,
13896 <parameter>description
</parameter> <type>text
</type> )
13899 Returns a table that describes each type of token a parser specified
13900 by OID can recognize.
13901 See
<xref linkend=
"textsearch-parser-testing"/> for details.
13904 <literal>ts_token_type(
3722)
</literal>
13905 <returnvalue>(
1,asciiword,
"Word, all ASCII") ...
</returnvalue>
13910 <entry role=
"func_table_entry"><para role=
"func_signature">
13912 <primary>ts_stat
</primary>
13914 <function>ts_stat
</function> (
<parameter>sqlquery
</parameter> <type>text
</type>
13915 <optional>,
<parameter>weights
</parameter> <type>text
</type> </optional> )
13916 <returnvalue>setof record
</returnvalue>
13917 (
<parameter>word
</parameter> <type>text
</type>,
13918 <parameter>ndoc
</parameter> <type>integer
</type>,
13919 <parameter>nentry
</parameter> <type>integer
</type> )
13922 Executes the
<parameter>sqlquery
</parameter>, which must return a
13923 single
<type>tsvector
</type> column, and returns statistics about each
13924 distinct lexeme contained in the data.
13925 See
<xref linkend=
"textsearch-statistics"/> for details.
13928 <literal>ts_stat('SELECT vector FROM apod')
</literal>
13929 <returnvalue>(foo,
10,
15) ...
</returnvalue>
13938 <sect1 id=
"functions-uuid">
13939 <title>UUID Functions
</title>
13941 <indexterm zone=
"datatype-uuid">
13942 <primary>UUID
</primary>
13943 <secondary>generating
</secondary>
13947 <primary>gen_random_uuid
</primary>
13951 <productname>PostgreSQL
</productname> includes one function to generate a UUID:
13953 <function>gen_random_uuid
</function> ()
<returnvalue>uuid
</returnvalue>
13955 This function returns a version
4 (random) UUID. This is the most commonly
13956 used type of UUID and is appropriate for most applications.
13960 The
<xref linkend=
"uuid-ossp"/> module provides additional functions that
13961 implement other standard algorithms for generating UUIDs.
13965 <productname>PostgreSQL
</productname> also provides the usual comparison
13966 operators shown in
<xref linkend=
"functions-comparison-op-table"/> for
13971 <sect1 id=
"functions-xml">
13973 <title>XML Functions
</title>
13976 <primary>XML Functions
</primary>
13980 The functions and function-like expressions described in this
13981 section operate on values of type
<type>xml
</type>. See
<xref
13982 linkend=
"datatype-xml"/> for information about the
<type>xml
</type>
13983 type. The function-like expressions
<function>xmlparse
</function>
13984 and
<function>xmlserialize
</function> for converting to and from
13985 type
<type>xml
</type> are documented there, not in this section.
13989 Use of most of these functions
13990 requires
<productname>PostgreSQL
</productname> to have been built
13991 with
<command>configure --with-libxml
</command>.
13994 <sect2 id=
"functions-producing-xml">
13995 <title>Producing XML Content
</title>
13998 A set of functions and function-like expressions is available for
13999 producing XML content from SQL data. As such, they are
14000 particularly suitable for formatting query results into XML
14001 documents for processing in client applications.
14004 <sect3 id=
"functions-producing-xml-xmlcomment">
14005 <title><literal>xmlcomment
</literal></title>
14008 <primary>xmlcomment
</primary>
14012 <function>xmlcomment
</function> (
<type>text
</type> )
<returnvalue>xml
</returnvalue>
14016 The function
<function>xmlcomment
</function> creates an XML value
14017 containing an XML comment with the specified text as content.
14018 The text cannot contain
<quote><literal>--
</literal></quote> or end with a
14019 <quote><literal>-
</literal></quote>, otherwise the resulting construct
14020 would not be a valid XML comment.
14021 If the argument is null, the result is null.
14027 SELECT xmlcomment('hello');
14036 <sect3 id=
"functions-producing-xml-xmlconcat">
14037 <title><literal>xmlconcat
</literal></title>
14040 <primary>xmlconcat
</primary>
14044 <function>xmlconcat
</function> (
<type>xml
</type> <optional>, ...
</optional> )
<returnvalue>xml
</returnvalue>
14048 The function
<function>xmlconcat
</function> concatenates a list
14049 of individual XML values to create a single value containing an
14050 XML content fragment. Null values are omitted; the result is
14051 only null if there are no nonnull arguments.
14057 SELECT xmlconcat('
<abc/>', '
<bar>foo
</bar>');
14060 ----------------------
14061 <abc/><bar>foo
</bar>
14066 XML declarations, if present, are combined as follows. If all
14067 argument values have the same XML version declaration, that
14068 version is used in the result, else no version is used. If all
14069 argument values have the standalone declaration value
14070 <quote>yes
</quote>, then that value is used in the result. If
14071 all argument values have a standalone declaration value and at
14072 least one is
<quote>no
</quote>, then that is used in the result.
14073 Else the result will have no standalone declaration. If the
14074 result is determined to require a standalone declaration but no
14075 version declaration, a version declaration with version
1.0 will
14076 be used because XML requires an XML declaration to contain a
14077 version declaration. Encoding declarations are ignored and
14078 removed in all cases.
14084 SELECT xmlconcat('
<?xml version=
"1.1"?><foo/>', '
<?xml version=
"1.1" standalone=
"no"?><bar/>');
14087 -----------------------------------
14088 <?xml version=
"1.1"?><foo/><bar/>
14093 <sect3 id=
"functions-producing-xml-xmlelement">
14094 <title><literal>xmlelement
</literal></title>
14097 <primary>xmlelement
</primary>
14101 <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>
14105 The
<function>xmlelement
</function> expression produces an XML
14106 element with the given name, attributes, and content.
14107 The
<replaceable>name
</replaceable>
14108 and
<replaceable>attname
</replaceable> items shown in the syntax are
14109 simple identifiers, not values. The
<replaceable>attvalue
</replaceable>
14110 and
<replaceable>content
</replaceable> items are expressions, which can
14111 yield any
<productname>PostgreSQL
</productname> data type. The
14112 argument(s) within
<literal>XMLATTRIBUTES
</literal> generate attributes
14113 of the XML element; the
<replaceable>content
</replaceable> value(s) are
14114 concatenated to form its content.
14120 SELECT xmlelement(name foo);
14126 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
14132 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
14135 -------------------------------------
14136 <foo bar=
"2007-01-26">content
</foo>
14141 Element and attribute names that are not valid XML names are
14142 escaped by replacing the offending characters by the sequence
14143 <literal>_x
<replaceable>HHHH
</replaceable>_
</literal>, where
14144 <replaceable>HHHH
</replaceable> is the character's Unicode
14145 codepoint in hexadecimal notation. For example:
14147 SELECT xmlelement(name
"foo$bar", xmlattributes('xyz' as
"a&b"));
14150 ----------------------------------
14151 <foo_x0024_bar a_x0026_b=
"xyz"/>
14156 An explicit attribute name need not be specified if the attribute
14157 value is a column reference, in which case the column's name will
14158 be used as the attribute name by default. In other cases, the
14159 attribute must be given an explicit name. So this example is
14162 CREATE TABLE test (a xml, b xml);
14163 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
14167 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
14168 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
14173 Element content, if specified, will be formatted according to
14174 its data type. If the content is itself of type
<type>xml
</type>,
14175 complex XML documents can be constructed. For example:
14177 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
14178 xmlelement(name abc),
14179 xmlcomment('test'),
14180 xmlelement(name xyz));
14183 ----------------------------------------------
14184 <foo bar=
"xyz"><abc/><!--test--><xyz/></foo>
14187 Content of other types will be formatted into valid XML character
14188 data. This means in particular that the characters
<,
>,
14189 and
& will be converted to entities. Binary data (data type
14190 <type>bytea
</type>) will be represented in base64 or hex
14191 encoding, depending on the setting of the configuration parameter
14192 <xref linkend=
"guc-xmlbinary"/>. The particular behavior for
14193 individual data types is expected to evolve in order to align the
14194 PostgreSQL mappings with those specified in SQL:
2006 and later,
14195 as discussed in
<xref linkend=
"functions-xml-limits-casts"/>.
14199 <sect3 id=
"functions-producing-xml-xmlforest">
14200 <title><literal>xmlforest
</literal></title>
14203 <primary>xmlforest
</primary>
14207 <function>xmlforest
</function> (
<replaceable>content
</replaceable> <optional> <literal>AS
</literal> <replaceable>name
</replaceable> </optional> <optional>, ...
</optional> )
<returnvalue>xml
</returnvalue>
14211 The
<function>xmlforest
</function> expression produces an XML
14212 forest (sequence) of elements using the given names and content.
14213 As for
<function>xmlelement
</function>,
14214 each
<replaceable>name
</replaceable> must be a simple identifier, while
14215 the
<replaceable>content
</replaceable> expressions can have any data
14222 SELECT xmlforest('abc' AS foo,
123 AS bar);
14225 ------------------------------
14226 <foo
>abc
</foo
><bar
>123</bar
>
14229 SELECT xmlforest(table_name, column_name)
14230 FROM information_schema.columns
14231 WHERE table_schema = 'pg_catalog';
14234 ------------------------------------
&zwsp;-----------------------------------
14235 <table_name
>pg_authid
</table_name
>&zwsp;<column_name
>rolname
</column_name
>
14236 <table_name
>pg_authid
</table_name
>&zwsp;<column_name
>rolsuper
</column_name
>
14240 As seen in the second example, the element name can be omitted if
14241 the content value is a column reference, in which case the column
14242 name is used by default. Otherwise, a name must be specified.
14246 Element names that are not valid XML names are escaped as shown
14247 for
<function>xmlelement
</function> above. Similarly, content
14248 data is escaped to make valid XML content, unless it is already
14249 of type
<type>xml
</type>.
14253 Note that XML forests are not valid XML documents if they consist
14254 of more than one element, so it might be useful to wrap
14255 <function>xmlforest
</function> expressions in
14256 <function>xmlelement
</function>.
14260 <sect3 id=
"functions-producing-xml-xmlpi">
14261 <title><literal>xmlpi
</literal></title>
14264 <primary>xmlpi
</primary>
14268 <function>xmlpi
</function> (
<literal>NAME
</literal> <replaceable>name
</replaceable> <optional>,
<replaceable>content
</replaceable> </optional> )
<returnvalue>xml
</returnvalue>
14272 The
<function>xmlpi
</function> expression creates an XML
14273 processing instruction.
14274 As for
<function>xmlelement
</function>,
14275 the
<replaceable>name
</replaceable> must be a simple identifier, while
14276 the
<replaceable>content
</replaceable> expression can have any data type.
14277 The
<replaceable>content
</replaceable>, if present, must not contain the
14278 character sequence
<literal>?
></literal>.
14284 SELECT xmlpi(name php, 'echo
"hello world";');
14287 -----------------------------
14288 <?php echo
"hello world";
?>
14293 <sect3 id=
"functions-producing-xml-xmlroot">
14294 <title><literal>xmlroot
</literal></title>
14297 <primary>xmlroot
</primary>
14301 <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>
14305 The
<function>xmlroot
</function> expression alters the properties
14306 of the root node of an XML value. If a version is specified,
14307 it replaces the value in the root node's version declaration; if a
14308 standalone setting is specified, it replaces the value in the
14309 root node's standalone declaration.
14314 SELECT xmlroot(xmlparse(document '
<?xml version=
"1.1"?><content>abc
</content>'),
14315 version '
1.0', standalone yes);
14318 ----------------------------------------
14319 <?xml version=
"1.0" standalone=
"yes"?>
14320 <content>abc
</content>
14325 <sect3 id=
"functions-xml-xmlagg">
14326 <title><literal>xmlagg
</literal></title>
14329 <primary>xmlagg
</primary>
14333 <function>xmlagg
</function> (
<type>xml
</type> )
<returnvalue>xml
</returnvalue>
14337 The function
<function>xmlagg
</function> is, unlike the other
14338 functions described here, an aggregate function. It concatenates the
14339 input values to the aggregate function call,
14340 much like
<function>xmlconcat
</function> does, except that concatenation
14341 occurs across rows rather than across expressions in a single row.
14342 See
<xref linkend=
"functions-aggregate"/> for additional information
14343 about aggregate functions.
14349 CREATE TABLE test (y int, x xml);
14350 INSERT INTO test VALUES (
1, '
<foo>abc
</foo>');
14351 INSERT INTO test VALUES (
2, '
<bar/>');
14352 SELECT xmlagg(x) FROM test;
14354 ----------------------
14355 <foo>abc
</foo><bar/>
14360 To determine the order of the concatenation, an
<literal>ORDER BY
</literal>
14361 clause may be added to the aggregate call as described in
14362 <xref linkend=
"syntax-aggregates"/>. For example:
14365 SELECT xmlagg(x ORDER BY y DESC) FROM test;
14367 ----------------------
14368 <bar/><foo>abc
</foo>
14373 The following non-standard approach used to be recommended
14374 in previous versions, and may still be useful in specific
14378 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
14380 ----------------------
14381 <bar/><foo>abc
</foo>
14387 <sect2 id=
"functions-xml-predicates">
14388 <title>XML Predicates
</title>
14391 The expressions described in this section check properties
14392 of
<type>xml
</type> values.
14395 <sect3 id=
"functions-producing-xml-is-document">
14396 <title><literal>IS DOCUMENT
</literal></title>
14399 <primary>IS DOCUMENT
</primary>
14403 <type>xml
</type> <literal>IS DOCUMENT
</literal> <returnvalue>boolean
</returnvalue>
14407 The expression
<literal>IS DOCUMENT
</literal> returns true if the
14408 argument XML value is a proper XML document, false if it is not
14409 (that is, it is a content fragment), or null if the argument is
14410 null. See
<xref linkend=
"datatype-xml"/> about the difference
14411 between documents and content fragments.
14415 <sect3 id=
"functions-producing-xml-is-not-document">
14416 <title><literal>IS NOT DOCUMENT
</literal></title>
14419 <primary>IS NOT DOCUMENT
</primary>
14423 <type>xml
</type> <literal>IS NOT DOCUMENT
</literal> <returnvalue>boolean
</returnvalue>
14427 The expression
<literal>IS NOT DOCUMENT
</literal> returns false if the
14428 argument XML value is a proper XML document, true if it is not (that is,
14429 it is a content fragment), or null if the argument is null.
14433 <sect3 id=
"xml-exists">
14434 <title><literal>XMLEXISTS
</literal></title>
14437 <primary>XMLEXISTS
</primary>
14441 <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>
14445 The function
<function>xmlexists
</function> evaluates an XPath
1.0
14446 expression (the first argument), with the passed XML value as its context
14447 item. The function returns false if the result of that evaluation
14448 yields an empty node-set, true if it yields any other value. The
14449 function returns null if any argument is null. A nonnull value
14450 passed as the context item must be an XML document, not a content
14451 fragment or any non-XML value.
14457 SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY VALUE '
<towns><town>Toronto
</town><town>Ottawa
</town></towns>');
14467 The
<literal>BY REF
</literal> and
<literal>BY VALUE
</literal> clauses
14468 are accepted in
<productname>PostgreSQL
</productname>, but are ignored,
14469 as discussed in
<xref linkend=
"functions-xml-limits-postgresql"/>.
14473 In the SQL standard, the
<function>xmlexists
</function> function
14474 evaluates an expression in the XML Query language,
14475 but
<productname>PostgreSQL
</productname> allows only an XPath
1.0
14476 expression, as discussed in
14477 <xref linkend=
"functions-xml-limits-xpath1"/>.
14481 <sect3 id=
"xml-is-well-formed">
14482 <title><literal>xml_is_well_formed
</literal></title>
14485 <primary>xml_is_well_formed
</primary>
14489 <primary>xml_is_well_formed_document
</primary>
14493 <primary>xml_is_well_formed_content
</primary>
14497 <function>xml_is_well_formed
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14498 <function>xml_is_well_formed_document
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14499 <function>xml_is_well_formed_content
</function> (
<type>text
</type> )
<returnvalue>boolean
</returnvalue>
14503 These functions check whether a
<type>text
</type> string represents
14504 well-formed XML, returning a Boolean result.
14505 <function>xml_is_well_formed_document
</function> checks for a well-formed
14506 document, while
<function>xml_is_well_formed_content
</function> checks
14507 for well-formed content.
<function>xml_is_well_formed
</function> does
14508 the former if the
<xref linkend=
"guc-xmloption"/> configuration
14509 parameter is set to
<literal>DOCUMENT
</literal>, or the latter if it is set to
14510 <literal>CONTENT
</literal>. This means that
14511 <function>xml_is_well_formed
</function> is useful for seeing whether
14512 a simple cast to type
<type>xml
</type> will succeed, whereas the other two
14513 functions are useful for seeing whether the corresponding variants of
14514 <function>XMLPARSE
</function> will succeed.
14521 SET xmloption TO DOCUMENT;
14522 SELECT xml_is_well_formed('<
>');
14524 --------------------
14528 SELECT xml_is_well_formed('
<abc/>');
14530 --------------------
14534 SET xmloption TO CONTENT;
14535 SELECT xml_is_well_formed('abc');
14537 --------------------
14541 SELECT xml_is_well_formed_document('
<pg:foo xmlns:
pg=
"http://postgresql.org/stuff">bar
</pg:foo>');
14542 xml_is_well_formed_document
14543 -----------------------------
14547 SELECT xml_is_well_formed_document('
<pg:foo xmlns:
pg=
"http://postgresql.org/stuff">bar
</my:foo>');
14548 xml_is_well_formed_document
14549 -----------------------------
14554 The last example shows that the checks include whether
14555 namespaces are correctly matched.
14560 <sect2 id=
"functions-xml-processing">
14561 <title>Processing XML
</title>
14564 To process values of data type
<type>xml
</type>, PostgreSQL offers
14565 the functions
<function>xpath
</function> and
14566 <function>xpath_exists
</function>, which evaluate XPath
1.0
14567 expressions, and the
<function>XMLTABLE
</function>
14571 <sect3 id=
"functions-xml-processing-xpath">
14572 <title><literal>xpath
</literal></title>
14575 <primary>XPath
</primary>
14579 <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>
14583 The function
<function>xpath
</function> evaluates the XPath
1.0
14584 expression
<parameter>xpath
</parameter> (given as text)
14585 against the XML value
14586 <parameter>xml
</parameter>. It returns an array of XML values
14587 corresponding to the node-set produced by the XPath expression.
14588 If the XPath expression returns a scalar value rather than a node-set,
14589 a single-element array is returned.
14593 The second argument must be a well formed XML document. In particular,
14594 it must have a single root node element.
14598 The optional third argument of the function is an array of namespace
14599 mappings. This array should be a two-dimensional
<type>text
</type> array with
14600 the length of the second axis being equal to
2 (i.e., it should be an
14601 array of arrays, each of which consists of exactly
2 elements).
14602 The first element of each array entry is the namespace name (alias), the
14603 second the namespace URI. It is not required that aliases provided in
14604 this array be the same as those being used in the XML document itself (in
14605 other words, both in the XML document and in the
<function>xpath
</function>
14606 function context, aliases are
<emphasis>local
</emphasis>).
14612 SELECT xpath('/my:a/text()', '
<my:a xmlns:
my=
"http://example.com">test
</my:a>',
14613 ARRAY[ARRAY['my', 'http://example.com']]);
14623 To deal with default (anonymous) namespaces, do something like this:
14625 SELECT xpath('//mydefns:b/text()', '
<a xmlns=
"http://example.com"><b>test
</b></a>',
14626 ARRAY[ARRAY['mydefns', 'http://example.com']]);
14636 <sect3 id=
"functions-xml-processing-xpath-exists">
14637 <title><literal>xpath_exists
</literal></title>
14640 <primary>xpath_exists
</primary>
14644 <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>
14648 The function
<function>xpath_exists
</function> is a specialized form
14649 of the
<function>xpath
</function> function. Instead of returning the
14650 individual XML values that satisfy the XPath
1.0 expression, this function
14651 returns a Boolean indicating whether the query was satisfied or not
14652 (specifically, whether it produced any value other than an empty node-set).
14653 This function is equivalent to the
<literal>XMLEXISTS
</literal> predicate,
14654 except that it also offers support for a namespace mapping argument.
14660 SELECT xpath_exists('/my:a/text()', '
<my:a xmlns:
my=
"http://example.com">test
</my:a>',
14661 ARRAY[ARRAY['my', 'http://example.com']]);
14671 <sect3 id=
"functions-xml-processing-xmltable">
14672 <title><literal>xmltable
</literal></title>
14675 <primary>xmltable
</primary>
14678 <indexterm zone=
"functions-xml-processing-xmltable">
14679 <primary>table function
</primary>
14680 <secondary>XMLTABLE
</secondary>
14684 <function>XMLTABLE
</function> (
14685 <optional> <literal>XMLNAMESPACES
</literal> (
<replaceable>namespace_uri
</replaceable> <literal>AS
</literal> <replaceable>namespace_name
</replaceable> <optional>, ...
</optional> ),
</optional>
14686 <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>
14687 <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>
14688 |
<literal>FOR ORDINALITY
</literal> }
14689 <optional>, ...
</optional>
14690 )
<returnvalue>setof record
</returnvalue>
14694 The
<function>xmltable
</function> expression produces a table based
14695 on an XML value, an XPath filter to extract rows, and a
14696 set of column definitions.
14697 Although it syntactically resembles a function, it can only appear
14698 as a table in a query's
<literal>FROM
</literal> clause.
14702 The optional
<literal>XMLNAMESPACES
</literal> clause gives a
14703 comma-separated list of namespace definitions, where
14704 each
<replaceable>namespace_uri
</replaceable> is a
<type>text
</type>
14705 expression and each
<replaceable>namespace_name
</replaceable> is a simple
14706 identifier. It specifies the XML namespaces used in the document and
14707 their aliases. A default namespace specification is not currently
14712 The required
<replaceable>row_expression
</replaceable> argument is an
14713 XPath
1.0 expression (given as
<type>text
</type>) that is evaluated,
14714 passing the XML value
<replaceable>document_expression
</replaceable> as
14715 its context item, to obtain a set of XML nodes. These nodes are what
14716 <function>xmltable
</function> transforms into output rows. No rows
14717 will be produced if the
<replaceable>document_expression
</replaceable>
14718 is null, nor if the
<replaceable>row_expression
</replaceable> produces
14719 an empty node-set or any value other than a node-set.
14723 <replaceable>document_expression
</replaceable> provides the context
14724 item for the
<replaceable>row_expression
</replaceable>. It must be a
14725 well-formed XML document; fragments/forests are not accepted.
14726 The
<literal>BY REF
</literal> and
<literal>BY VALUE
</literal> clauses
14727 are accepted but ignored, as discussed in
14728 <xref linkend=
"functions-xml-limits-postgresql"/>.
14732 In the SQL standard, the
<function>xmltable
</function> function
14733 evaluates expressions in the XML Query language,
14734 but
<productname>PostgreSQL
</productname> allows only XPath
1.0
14735 expressions, as discussed in
14736 <xref linkend=
"functions-xml-limits-xpath1"/>.
14740 The required
<literal>COLUMNS
</literal> clause specifies the
14741 column(s) that will be produced in the output table.
14742 See the syntax summary above for the format.
14743 A name is required for each column, as is a data type
14744 (unless
<literal>FOR ORDINALITY
</literal> is specified, in which case
14745 type
<type>integer
</type> is implicit). The path, default and
14746 nullability clauses are optional.
14750 A column marked
<literal>FOR ORDINALITY
</literal> will be populated
14751 with row numbers, starting with
1, in the order of nodes retrieved from
14752 the
<replaceable>row_expression
</replaceable>'s result node-set.
14753 At most one column may be marked
<literal>FOR ORDINALITY
</literal>.
14758 XPath
1.0 does not specify an order for nodes in a node-set, so code
14759 that relies on a particular order of the results will be
14760 implementation-dependent. Details can be found in
14761 <xref linkend=
"xml-xpath-1-specifics"/>.
14766 The
<replaceable>column_expression
</replaceable> for a column is an
14767 XPath
1.0 expression that is evaluated for each row, with the current
14768 node from the
<replaceable>row_expression
</replaceable> result as its
14769 context item, to find the value of the column. If
14770 no
<replaceable>column_expression
</replaceable> is given, then the
14771 column name is used as an implicit path.
14775 If a column's XPath expression returns a non-XML value (which is limited
14776 to string, boolean, or double in XPath
1.0) and the column has a
14777 PostgreSQL type other than
<type>xml
</type>, the column will be set
14778 as if by assigning the value's string representation to the PostgreSQL
14779 type. (If the value is a boolean, its string representation is taken
14780 to be
<literal>1</literal> or
<literal>0</literal> if the output
14781 column's type category is numeric, otherwise
<literal>true
</literal> or
14782 <literal>false
</literal>.)
14786 If a column's XPath expression returns a non-empty set of XML nodes
14787 and the column's PostgreSQL type is
<type>xml
</type>, the column will
14788 be assigned the expression result exactly, if it is of document or
14792 A result containing more than one element node at the top level, or
14793 non-whitespace text outside of an element, is an example of content form.
14794 An XPath result can be of neither form, for example if it returns an
14795 attribute node selected from the element that contains it. Such a result
14796 will be put into content form with each such disallowed node replaced by
14797 its string value, as defined for the XPath
1.0
14798 <function>string
</function> function.
14804 A non-XML result assigned to an
<type>xml
</type> output column produces
14805 content, a single text node with the string value of the result.
14806 An XML result assigned to a column of any other type may not have more than
14807 one node, or an error is raised. If there is exactly one node, the column
14808 will be set as if by assigning the node's string
14809 value (as defined for the XPath
1.0 <function>string
</function> function)
14810 to the PostgreSQL type.
14814 The string value of an XML element is the concatenation, in document order,
14815 of all text nodes contained in that element and its descendants. The string
14816 value of an element with no descendant text nodes is an
14817 empty string (not
<literal>NULL
</literal>).
14818 Any
<literal>xsi:nil
</literal> attributes are ignored.
14819 Note that the whitespace-only
<literal>text()
</literal> node between two non-text
14820 elements is preserved, and that leading whitespace on a
<literal>text()
</literal>
14821 node is not flattened.
14822 The XPath
1.0 <function>string
</function> function may be consulted for the
14823 rules defining the string value of other XML node types and non-XML values.
14827 The conversion rules presented here are not exactly those of the SQL
14828 standard, as discussed in
<xref linkend=
"functions-xml-limits-casts"/>.
14832 If the path expression returns an empty node-set
14833 (typically, when it does not match)
14834 for a given row, the column will be set to
<literal>NULL
</literal>, unless
14835 a
<replaceable>default_expression
</replaceable> is specified; then the
14836 value resulting from evaluating that expression is used.
14840 A
<replaceable>default_expression
</replaceable>, rather than being
14841 evaluated immediately when
<function>xmltable
</function> is called,
14842 is evaluated each time a default is needed for the column.
14843 If the expression qualifies as stable or immutable, the repeat
14844 evaluation may be skipped.
14845 This means that you can usefully use volatile functions like
14846 <function>nextval
</function> in
14847 <replaceable>default_expression
</replaceable>.
14851 Columns may be marked
<literal>NOT NULL
</literal>. If the
14852 <replaceable>column_expression
</replaceable> for a
<literal>NOT
14853 NULL
</literal> column does not match anything and there is
14854 no
<literal>DEFAULT
</literal> or
14855 the
<replaceable>default_expression
</replaceable> also evaluates to null,
14856 an error is reported.
14862 CREATE TABLE xmldata AS SELECT
14866 <COUNTRY_ID>AU
</COUNTRY_ID>
14867 <COUNTRY_NAME>Australia
</COUNTRY_NAME>
14870 <COUNTRY_ID>JP
</COUNTRY_ID>
14871 <COUNTRY_NAME>Japan
</COUNTRY_NAME>
14872 <PREMIER_NAME>Shinzo Abe
</PREMIER_NAME>
14873 <SIZE unit=
"sq_mi">145935</SIZE>
14876 <COUNTRY_ID>SG
</COUNTRY_ID>
14877 <COUNTRY_NAME>Singapore
</COUNTRY_NAME>
14878 <SIZE unit=
"sq_km">697</SIZE>
14885 XMLTABLE('//ROWS/ROW'
14887 COLUMNS id int PATH '@id',
14888 ordinality FOR ORDINALITY,
14889 "COUNTRY_NAME" text,
14890 country_id text PATH 'COUNTRY_ID',
14891 size_sq_km float PATH 'SIZE[@unit =
"sq_km"]',
14892 size_other text PATH
14893 'concat(SIZE[@unit!=
"sq_km"],
" ", SIZE[@unit!=
"sq_km"]/@unit)',
14894 premier_name text PATH 'PREMIER_NAME' DEFAULT 'not specified');
14896 id | ordinality | COUNTRY_NAME | country_id | size_sq_km | size_other | premier_name
14897 ----+------------+--------------+------------+------------+--------------+---------------
14898 1 |
1 | Australia | AU | | | not specified
14899 5 |
2 | Japan | JP | |
145935 sq_mi | Shinzo Abe
14900 6 |
3 | Singapore | SG |
697 | | not specified
14903 The following example shows concatenation of multiple text() nodes,
14904 usage of the column name as XPath filter, and the treatment of whitespace,
14905 XML comments and processing instructions:
14908 CREATE TABLE xmlelements AS SELECT
14911 <element> Hello
<!-- xyxxz -->2a2
<?aaaaa?> <!--x--> bbb
<x>xxx
</x>CC
</element>
14916 FROM xmlelements, XMLTABLE('/root' PASSING data COLUMNS element text);
14918 -------------------------
14924 The following example illustrates how
14925 the
<literal>XMLNAMESPACES
</literal> clause can be used to specify
14926 a list of namespaces
14927 used in the XML document as well as in the XPath expressions:
14930 WITH xmldata(data) AS (VALUES ('
14931 <example xmlns=
"http://example.com/myns" xmlns:
B=
"http://example.com/b">
14932 <item foo=
"1" B:
bar=
"2"/>
14933 <item foo=
"3" B:
bar=
"4"/>
14934 <item foo=
"4" B:
bar=
"5"/>
14938 FROM XMLTABLE(XMLNAMESPACES('http://example.com/myns' AS x,
14939 'http://example.com/b' AS
"B"),
14940 '/x:example/x:item'
14941 PASSING (SELECT data FROM xmldata)
14942 COLUMNS foo int PATH '@foo',
14943 bar int PATH '@B:bar');
14955 <sect2 id=
"functions-xml-mapping">
14956 <title>Mapping Tables to XML
</title>
14958 <indexterm zone=
"functions-xml-mapping">
14959 <primary>XML export
</primary>
14963 The following functions map the contents of relational tables to
14964 XML values. They can be thought of as XML export functionality:
14966 <function>table_to_xml
</function> (
<parameter>table
</parameter> <type>regclass
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
14967 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
14968 <function>query_to_xml
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
14969 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
14970 <function>cursor_to_xml
</function> (
<parameter>cursor
</parameter> <type>refcursor
</type>,
<parameter>count
</parameter> <type>integer
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
14971 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
14976 <function>table_to_xml
</function> maps the content of the named
14977 table, passed as parameter
<parameter>table
</parameter>. The
14978 <type>regclass
</type> type accepts strings identifying tables using the
14979 usual notation, including optional schema qualification and
14980 double quotes (see
<xref linkend=
"datatype-oid"/> for details).
14981 <function>query_to_xml
</function> executes the
14982 query whose text is passed as parameter
14983 <parameter>query
</parameter> and maps the result set.
14984 <function>cursor_to_xml
</function> fetches the indicated number of
14985 rows from the cursor specified by the parameter
14986 <parameter>cursor
</parameter>. This variant is recommended if
14987 large tables have to be mapped, because the result value is built
14988 up in memory by each function.
14992 If
<parameter>tableforest
</parameter> is false, then the resulting
14993 XML document looks like this:
14997 <columnname1>data
</columnname1>
14998 <columnname2>data
</columnname2>
15009 If
<parameter>tableforest
</parameter> is true, the result is an
15010 XML content fragment that looks like this:
15013 <columnname1>data
</columnname1>
15014 <columnname2>data
</columnname2>
15024 If no table name is available, that is, when mapping a query or a
15025 cursor, the string
<literal>table
</literal> is used in the first
15026 format,
<literal>row
</literal> in the second format.
15030 The choice between these formats is up to the user. The first
15031 format is a proper XML document, which will be important in many
15032 applications. The second format tends to be more useful in the
15033 <function>cursor_to_xml
</function> function if the result values are to be
15034 reassembled into one document later on. The functions for
15035 producing XML content discussed above, in particular
15036 <function>xmlelement
</function>, can be used to alter the results
15041 The data values are mapped in the same way as described for the
15042 function
<function>xmlelement
</function> above.
15046 The parameter
<parameter>nulls
</parameter> determines whether null
15047 values should be included in the output. If true, null values in
15048 columns are represented as:
15050 <columnname xsi:
nil=
"true"/>
15052 where
<literal>xsi
</literal> is the XML namespace prefix for XML
15053 Schema Instance. An appropriate namespace declaration will be
15054 added to the result value. If false, columns containing null
15055 values are simply omitted from the output.
15059 The parameter
<parameter>targetns
</parameter> specifies the
15060 desired XML namespace of the result. If no particular namespace
15061 is wanted, an empty string should be passed.
15065 The following functions return XML Schema documents describing the
15066 mappings performed by the corresponding functions above:
15068 <function>table_to_xmlschema
</function> (
<parameter>table
</parameter> <type>regclass
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15069 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15070 <function>query_to_xmlschema
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15071 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15072 <function>cursor_to_xmlschema
</function> (
<parameter>cursor
</parameter> <type>refcursor
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15073 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15075 It is essential that the same parameters are passed in order to
15076 obtain matching XML data mappings and XML Schema documents.
15080 The following functions produce XML data mappings and the
15081 corresponding XML Schema in one document (or forest), linked
15082 together. They can be useful where self-contained and
15083 self-describing results are wanted:
15085 <function>table_to_xml_and_xmlschema
</function> (
<parameter>table
</parameter> <type>regclass
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15086 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15087 <function>query_to_xml_and_xmlschema
</function> (
<parameter>query
</parameter> <type>text
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15088 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15093 In addition, the following functions are available to produce
15094 analogous mappings of entire schemas or the entire current
15097 <function>schema_to_xml
</function> (
<parameter>schema
</parameter> <type>name
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15098 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15099 <function>schema_to_xmlschema
</function> (
<parameter>schema
</parameter> <type>name
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15100 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15101 <function>schema_to_xml_and_xmlschema
</function> (
<parameter>schema
</parameter> <type>name
</type>,
<parameter>nulls
</parameter> <type>boolean
</type>,
15102 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15104 <function>database_to_xml
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15105 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15106 <function>database_to_xmlschema
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15107 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15108 <function>database_to_xml_and_xmlschema
</function> (
<parameter>nulls
</parameter> <type>boolean
</type>,
15109 <parameter>tableforest
</parameter> <type>boolean
</type>,
<parameter>targetns
</parameter> <type>text
</type> )
<returnvalue>xml
</returnvalue>
15112 These functions ignore tables that are not readable by the current user.
15113 The database-wide functions additionally ignore schemas that the current
15114 user does not have
<literal>USAGE
</literal> (lookup) privilege for.
15118 Note that these potentially produce a lot of data, which needs to
15119 be built up in memory. When requesting content mappings of large
15120 schemas or databases, it might be worthwhile to consider mapping the
15121 tables separately instead, possibly even through a cursor.
15125 The result of a schema content mapping looks like this:
15136 </schemaname>]]
></screen>
15138 where the format of a table mapping depends on the
15139 <parameter>tableforest
</parameter> parameter as explained above.
15143 The result of a database content mapping looks like this:
15158 </dbname>]]
></screen>
15160 where the schema mapping is as above.
15164 As an example of using the output produced by these functions,
15165 <xref linkend=
"xslt-xml-html"/> shows an XSLT stylesheet that
15166 converts the output of
15167 <function>table_to_xml_and_xmlschema
</function> to an HTML
15168 document containing a tabular rendition of the table data. In a
15169 similar manner, the results from these functions can be
15170 converted into other XML-based formats.
15173 <example id=
"xslt-xml-html">
15174 <title>XSLT Stylesheet for Converting SQL/XML Output to HTML
</title>
15175 <programlisting><![CDATA[
15176 <?xml version=
"1.0"?>
15177 <xsl:stylesheet version=
"1.0"
15178 xmlns:
xsl=
"http://www.w3.org/1999/XSL/Transform"
15179 xmlns:
xsd=
"http://www.w3.org/2001/XMLSchema"
15180 xmlns=
"http://www.w3.org/1999/xhtml"
15183 <xsl:output method=
"xml"
15184 doctype-system=
"http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
15185 doctype-public=
"-//W3C/DTD XHTML 1.0 Strict//EN"
15188 <xsl:template match=
"/*">
15189 <xsl:variable name=
"schema" select=
"//xsd:schema"/>
15190 <xsl:variable name=
"tabletypename"
15191 select=
"$schema/xsd:element[@name=name(current())]/@type"/>
15192 <xsl:variable name=
"rowtypename"
15193 select=
"$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
15197 <title><xsl:value-of select=
"name(current())"/></title>
15202 <xsl:for-each select=
"$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
15203 <th><xsl:value-of select=
"."/></th>
15207 <xsl:for-each select=
"row">
15209 <xsl:for-each select=
"*">
15210 <td><xsl:value-of select=
"."/></td>
15220 ]]
></programlisting>
15225 <sect1 id=
"functions-json">
15226 <title>JSON Functions and Operators
</title>
15228 <indexterm zone=
"functions-json">
15229 <primary>JSON
</primary>
15230 <secondary>functions and operators
</secondary>
15234 This section describes:
15239 functions and operators for processing and creating JSON data
15244 the SQL/JSON path language
15251 To learn more about the SQL/JSON standard, see
15252 <xref linkend=
"sqltr-19075-6"/>. For details on JSON types
15253 supported in
<productname>PostgreSQL
</productname>,
15254 see
<xref linkend=
"datatype-json"/>.
15257 <sect2 id=
"functions-json-processing">
15258 <title>Processing and Creating JSON Data
</title>
15261 <xref linkend=
"functions-json-op-table"/> shows the operators that
15262 are available for use with JSON data types (see
<xref
15263 linkend=
"datatype-json"/>).
15264 In addition, the usual comparison operators shown in
<xref
15265 linkend=
"functions-comparison-op-table"/> are available for
15266 <type>jsonb
</type>, though not for
<type>json
</type>. The comparison
15267 operators follow the ordering rules for B-tree operations outlined in
15268 <xref linkend=
"json-indexing"/>.
15269 See also
<xref linkend=
"functions-aggregate"/> for the aggregate
15270 function
<function>json_agg
</function> which aggregates record
15271 values as JSON, the aggregate function
15272 <function>json_object_agg
</function> which aggregates pairs of values
15273 into a JSON object, and their
<type>jsonb
</type> equivalents,
15274 <function>jsonb_agg
</function> and
<function>jsonb_object_agg
</function>.
15277 <table id=
"functions-json-op-table">
15278 <title><type>json
</type> and
<type>jsonb
</type> Operators
</title>
15282 <entry role=
"func_table_entry"><para role=
"func_signature">
15296 <entry role=
"func_table_entry"><para role=
"func_signature">
15297 <type>json
</type> <literal>-
></literal> <type>integer
</type>
15298 <returnvalue>json
</returnvalue>
15300 <para role=
"func_signature">
15301 <type>jsonb
</type> <literal>-
></literal> <type>integer
</type>
15302 <returnvalue>jsonb
</returnvalue>
15305 Extracts
<parameter>n
</parameter>'th element of JSON array
15306 (array elements are indexed from zero, but negative integers count
15310 <literal>'[{
"a":
"foo"},{
"b":
"bar"},{
"c":
"baz"}]'::json -
> 2</literal>
15311 <returnvalue>{
"c":
"baz"}
</returnvalue>
15314 <literal>'[{
"a":
"foo"},{
"b":
"bar"},{
"c":
"baz"}]'::json -
> -
3</literal>
15315 <returnvalue>{
"a":
"foo"}
</returnvalue>
15320 <entry role=
"func_table_entry"><para role=
"func_signature">
15321 <type>json
</type> <literal>-
></literal> <type>text
</type>
15322 <returnvalue>json
</returnvalue>
15324 <para role=
"func_signature">
15325 <type>jsonb
</type> <literal>-
></literal> <type>text
</type>
15326 <returnvalue>jsonb
</returnvalue>
15329 Extracts JSON object field with the given key.
15332 <literal>'{
"a": {
"b":
"foo"}}'::json -
> 'a'
</literal>
15333 <returnvalue>{
"b":
"foo"}
</returnvalue>
15338 <entry role=
"func_table_entry"><para role=
"func_signature">
15339 <type>json
</type> <literal>-
>></literal> <type>integer
</type>
15340 <returnvalue>text
</returnvalue>
15342 <para role=
"func_signature">
15343 <type>jsonb
</type> <literal>-
>></literal> <type>integer
</type>
15344 <returnvalue>text
</returnvalue>
15347 Extracts
<parameter>n
</parameter>'th element of JSON array,
15348 as
<type>text
</type>.
15351 <literal>'[
1,
2,
3]'::json -
>> 2</literal>
15352 <returnvalue>3</returnvalue>
15357 <entry role=
"func_table_entry"><para role=
"func_signature">
15358 <type>json
</type> <literal>-
>></literal> <type>text
</type>
15359 <returnvalue>text
</returnvalue>
15361 <para role=
"func_signature">
15362 <type>jsonb
</type> <literal>-
>></literal> <type>text
</type>
15363 <returnvalue>text
</returnvalue>
15366 Extracts JSON object field with the given key, as
<type>text
</type>.
15369 <literal>'{
"a":
1,
"b":
2}'::json -
>> 'b'
</literal>
15370 <returnvalue>2</returnvalue>
15375 <entry role=
"func_table_entry"><para role=
"func_signature">
15376 <type>json
</type> <literal>#
></literal> <type>text[]
</type>
15377 <returnvalue>json
</returnvalue>
15379 <para role=
"func_signature">
15380 <type>jsonb
</type> <literal>#
></literal> <type>text[]
</type>
15381 <returnvalue>jsonb
</returnvalue>
15384 Extracts JSON sub-object at the specified path, where path elements
15385 can be either field keys or array indexes.
15388 <literal>'{
"a": {
"b": [
"foo",
"bar"]}}'::json #
> '{a,b,
1}'
</literal>
15389 <returnvalue>"bar"</returnvalue>
15394 <entry role=
"func_table_entry"><para role=
"func_signature">
15395 <type>json
</type> <literal>#
>></literal> <type>text[]
</type>
15396 <returnvalue>text
</returnvalue>
15398 <para role=
"func_signature">
15399 <type>jsonb
</type> <literal>#
>></literal> <type>text[]
</type>
15400 <returnvalue>text
</returnvalue>
15403 Extracts JSON sub-object at the specified path as
<type>text
</type>.
15406 <literal>'{
"a": {
"b": [
"foo",
"bar"]}}'::json #
>> '{a,b,
1}'
</literal>
15407 <returnvalue>bar
</returnvalue>
15416 The field/element/path extraction operators return NULL, rather than
15417 failing, if the JSON input does not have the right structure to match
15418 the request; for example if no such key or array element exists.
15423 Some further operators exist only for
<type>jsonb
</type>, as shown
15424 in
<xref linkend=
"functions-jsonb-op-table"/>.
15425 <xref linkend=
"json-indexing"/>
15426 describes how these operators can be used to effectively search indexed
15427 <type>jsonb
</type> data.
15430 <table id=
"functions-jsonb-op-table">
15431 <title>Additional
<type>jsonb
</type> Operators
</title>
15435 <entry role=
"func_table_entry"><para role=
"func_signature">
15449 <entry role=
"func_table_entry"><para role=
"func_signature">
15450 <type>jsonb
</type> <literal>@
></literal> <type>jsonb
</type>
15451 <returnvalue>boolean
</returnvalue>
15454 Does the first JSON value contain the second?
15455 (See
<xref linkend=
"json-containment"/> for details about containment.)
15458 <literal>'{
"a":
1,
"b":
2}'::jsonb
@> '{
"b":
2}'::jsonb
</literal>
15459 <returnvalue>t
</returnvalue>
15464 <entry role=
"func_table_entry"><para role=
"func_signature">
15465 <type>jsonb
</type> <literal><@
</literal> <type>jsonb
</type>
15466 <returnvalue>boolean
</returnvalue>
15469 Is the first JSON value contained in the second?
15472 <literal>'{
"b":
2}'::jsonb
<@ '{
"a":
1,
"b":
2}'::jsonb
</literal>
15473 <returnvalue>t
</returnvalue>
15478 <entry role=
"func_table_entry"><para role=
"func_signature">
15479 <type>jsonb
</type> <literal>?
</literal> <type>text
</type>
15480 <returnvalue>boolean
</returnvalue>
15483 Does the text string exist as a top-level key or array element within
15487 <literal>'{
"a":
1,
"b":
2}'::jsonb ? 'b'
</literal>
15488 <returnvalue>t
</returnvalue>
15491 <literal>'[
"a",
"b",
"c"]'::jsonb ? 'b'
</literal>
15492 <returnvalue>t
</returnvalue>
15497 <entry role=
"func_table_entry"><para role=
"func_signature">
15498 <type>jsonb
</type> <literal>?|
</literal> <type>text[]
</type>
15499 <returnvalue>boolean
</returnvalue>
15502 Do any of the strings in the text array exist as top-level keys or
15506 <literal>'{
"a":
1,
"b":
2,
"c":
3}'::jsonb ?| array['b', 'd']
</literal>
15507 <returnvalue>t
</returnvalue>
15512 <entry role=
"func_table_entry"><para role=
"func_signature">
15513 <type>jsonb
</type> <literal>?
&</literal> <type>text[]
</type>
15514 <returnvalue>boolean
</returnvalue>
15517 Do all of the strings in the text array exist as top-level keys or
15521 <literal>'[
"a",
"b",
"c"]'::jsonb ?
& array['a', 'b']
</literal>
15522 <returnvalue>t
</returnvalue>
15527 <entry role=
"func_table_entry"><para role=
"func_signature">
15528 <type>jsonb
</type> <literal>||
</literal> <type>jsonb
</type>
15529 <returnvalue>jsonb
</returnvalue>
15532 Concatenates two
<type>jsonb
</type> values.
15533 Concatenating two arrays generates an array containing all the
15534 elements of each input. Concatenating two objects generates an
15535 object containing the union of their
15536 keys, taking the second object's value when there are duplicate keys.
15537 All other cases are treated by converting a non-array input into a
15538 single-element array, and then proceeding as for two arrays.
15539 Does not operate recursively: only the top-level array or object
15540 structure is merged.
15543 <literal>'[
"a",
"b"]'::jsonb || '[
"a",
"d"]'::jsonb
</literal>
15544 <returnvalue>[
"a",
"b",
"a",
"d"]
</returnvalue>
15547 <literal>'{
"a":
"b"}'::jsonb || '{
"c":
"d"}'::jsonb
</literal>
15548 <returnvalue>{
"a":
"b",
"c":
"d"}
</returnvalue>
15551 <literal>'[
1,
2]'::jsonb || '
3'::jsonb
</literal>
15552 <returnvalue>[
1,
2,
3]
</returnvalue>
15555 <literal>'{
"a":
"b"}'::jsonb || '
42'::jsonb
</literal>
15556 <returnvalue>[{
"a":
"b"},
42]
</returnvalue>
15559 To append an array to another array as a single entry, wrap it
15560 in an additional layer of array, for example:
15563 <literal>'[
1,
2]'::jsonb || jsonb_build_array('[
3,
4]'::jsonb)
</literal>
15564 <returnvalue>[
1,
2, [
3,
4]]
</returnvalue>
15569 <entry role=
"func_table_entry"><para role=
"func_signature">
15570 <type>jsonb
</type> <literal>-
</literal> <type>text
</type>
15571 <returnvalue>jsonb
</returnvalue>
15574 Deletes a key (and its value) from a JSON object, or matching string
15575 value(s) from a JSON array.
15578 <literal>'{
"a":
"b",
"c":
"d"}'::jsonb - 'a'
</literal>
15579 <returnvalue>{
"c":
"d"}
</returnvalue>
15582 <literal>'[
"a",
"b",
"c",
"b"]'::jsonb - 'b'
</literal>
15583 <returnvalue>[
"a",
"c"]
</returnvalue>
15588 <entry role=
"func_table_entry"><para role=
"func_signature">
15589 <type>jsonb
</type> <literal>-
</literal> <type>text[]
</type>
15590 <returnvalue>jsonb
</returnvalue>
15593 Deletes all matching keys or array elements from the left operand.
15596 <literal>'{
"a":
"b",
"c":
"d"}'::jsonb - '{a,c}'::text[]
</literal>
15597 <returnvalue>{}
</returnvalue>
15602 <entry role=
"func_table_entry"><para role=
"func_signature">
15603 <type>jsonb
</type> <literal>-
</literal> <type>integer
</type>
15604 <returnvalue>jsonb
</returnvalue>
15607 Deletes the array element with specified index (negative
15608 integers count from the end). Throws an error if JSON value
15612 <literal>'[
"a",
"b"]'::jsonb -
1 </literal>
15613 <returnvalue>[
"a"]
</returnvalue>
15618 <entry role=
"func_table_entry"><para role=
"func_signature">
15619 <type>jsonb
</type> <literal>#-
</literal> <type>text[]
</type>
15620 <returnvalue>jsonb
</returnvalue>
15623 Deletes the field or array element at the specified path, where path
15624 elements can be either field keys or array indexes.
15627 <literal>'[
"a", {
"b":
1}]'::jsonb #- '{
1,b}'
</literal>
15628 <returnvalue>[
"a", {}]
</returnvalue>
15633 <entry role=
"func_table_entry"><para role=
"func_signature">
15634 <type>jsonb
</type> <literal>@?
</literal> <type>jsonpath
</type>
15635 <returnvalue>boolean
</returnvalue>
15638 Does JSON path return any item for the specified JSON value?
15641 <literal>'{
"a":[
1,
2,
3,
4,
5]}'::jsonb @? '$.a[*] ? (@
> 2)'
</literal>
15642 <returnvalue>t
</returnvalue>
15647 <entry role=
"func_table_entry"><para role=
"func_signature">
15648 <type>jsonb
</type> <literal>@@
</literal> <type>jsonpath
</type>
15649 <returnvalue>boolean
</returnvalue>
15652 Returns the result of a JSON path predicate check for the
15653 specified JSON value. Only the first item of the result is taken into
15654 account. If the result is not Boolean, then
<literal>NULL
</literal>
15658 <literal>'{
"a":[
1,
2,
3,
4,
5]}'::jsonb @@ '$.a[*]
> 2'
</literal>
15659 <returnvalue>t
</returnvalue>
15668 The
<type>jsonpath
</type> operators
<literal>@?
</literal>
15669 and
<literal>@@
</literal> suppress the following errors: missing object
15670 field or array element, unexpected JSON item type, datetime and numeric
15671 errors. The
<type>jsonpath
</type>-related functions described below can
15672 also be told to suppress these types of errors. This behavior might be
15673 helpful when searching JSON document collections of varying structure.
15678 <xref linkend=
"functions-json-creation-table"/> shows the functions that are
15679 available for constructing
<type>json
</type> and
<type>jsonb
</type> values.
15682 <table id=
"functions-json-creation-table">
15683 <title>JSON Creation Functions
</title>
15687 <entry role=
"func_table_entry"><para role=
"func_signature">
15701 <entry role=
"func_table_entry"><para role=
"func_signature">
15703 <primary>to_json
</primary>
15705 <function>to_json
</function> (
<type>anyelement
</type> )
15706 <returnvalue>json
</returnvalue>
15708 <para role=
"func_signature">
15710 <primary>to_jsonb
</primary>
15712 <function>to_jsonb
</function> (
<type>anyelement
</type> )
15713 <returnvalue>jsonb
</returnvalue>
15716 Converts any SQL value to
<type>json
</type> or
<type>jsonb
</type>.
15717 Arrays and composites are converted recursively to arrays and
15718 objects (multidimensional arrays become arrays of arrays in JSON).
15719 Otherwise, if there is a cast from the SQL data type
15720 to
<type>json
</type>, the cast function will be used to perform the
15721 conversion;
<footnote>
15723 For example, the
<xref linkend=
"hstore"/> extension has a cast
15724 from
<type>hstore
</type> to
<type>json
</type>, so that
15725 <type>hstore
</type> values converted via the JSON creation functions
15726 will be represented as JSON objects, not as primitive string values.
15729 otherwise, a scalar JSON value is produced. For any scalar other than
15730 a number, a Boolean, or a null value, the text representation will be
15731 used, with escaping as necessary to make it a valid JSON string value.
15734 <literal>to_json('Fred said
"Hi."'::text)
</literal>
15735 <returnvalue>"Fred said \"Hi.\
""</returnvalue>
15738 <literal>to_jsonb(row(
42, 'Fred said
"Hi."'::text))
</literal>
15739 <returnvalue>{
"f1":
42,
"f2":
"Fred said \"Hi.\
""}
</returnvalue>
15744 <entry role=
"func_table_entry"><para role=
"func_signature">
15746 <primary>array_to_json
</primary>
15748 <function>array_to_json
</function> (
<type>anyarray
</type> <optional>,
<type>boolean
</type> </optional> )
15749 <returnvalue>json
</returnvalue>
15752 Converts an SQL array to a JSON array. The behavior is the same
15753 as
<function>to_json
</function> except that line feeds will be added
15754 between top-level array elements if the optional boolean parameter is
15758 <literal>array_to_json('{{
1,
5},{
99,
100}}'::int[])
</literal>
15759 <returnvalue>[[
1,
5],[
99,
100]]
</returnvalue>
15764 <entry role=
"func_table_entry"><para role=
"func_signature">
15766 <primary>row_to_json
</primary>
15768 <function>row_to_json
</function> (
<type>record
</type> <optional>,
<type>boolean
</type> </optional> )
15769 <returnvalue>json
</returnvalue>
15772 Converts an SQL composite value to a JSON object. The behavior is the
15773 same as
<function>to_json
</function> except that line feeds will be
15774 added between top-level elements if the optional boolean parameter is
15778 <literal>row_to_json(row(
1,'foo'))
</literal>
15779 <returnvalue>{
"f1":
1,
"f2":
"foo"}
</returnvalue>
15784 <entry role=
"func_table_entry"><para role=
"func_signature">
15786 <primary>json_build_array
</primary>
15788 <function>json_build_array
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
15789 <returnvalue>json
</returnvalue>
15791 <para role=
"func_signature">
15793 <primary>jsonb_build_array
</primary>
15795 <function>jsonb_build_array
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
15796 <returnvalue>jsonb
</returnvalue>
15799 Builds a possibly-heterogeneously-typed JSON array out of a variadic
15800 argument list. Each argument is converted as
15801 per
<function>to_json
</function> or
<function>to_jsonb
</function>.
15804 <literal>json_build_array(
1,
2, 'foo',
4,
5)
</literal>
15805 <returnvalue>[
1,
2,
"foo",
4,
5]
</returnvalue>
15810 <entry role=
"func_table_entry"><para role=
"func_signature">
15812 <primary>json_build_object
</primary>
15814 <function>json_build_object
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
15815 <returnvalue>json
</returnvalue>
15817 <para role=
"func_signature">
15819 <primary>jsonb_build_object
</primary>
15821 <function>jsonb_build_object
</function> (
<literal>VARIADIC
</literal> <type>"any"</type> )
15822 <returnvalue>jsonb
</returnvalue>
15825 Builds a JSON object out of a variadic argument list. By convention,
15826 the argument list consists of alternating keys and values. Key
15827 arguments are coerced to text; value arguments are converted as
15828 per
<function>to_json
</function> or
<function>to_jsonb
</function>.
15831 <literal>json_build_object('foo',
1,
2, row(
3,'bar'))
</literal>
15832 <returnvalue>{
"foo" :
1,
"2" : {
"f1":
3,
"f2":
"bar"}}
</returnvalue>
15837 <entry role=
"func_table_entry"><para role=
"func_signature">
15839 <primary>json_object
</primary>
15841 <function>json_object
</function> (
<type>text[]
</type> )
15842 <returnvalue>json
</returnvalue>
15844 <para role=
"func_signature">
15846 <primary>jsonb_object
</primary>
15848 <function>jsonb_object
</function> (
<type>text[]
</type> )
15849 <returnvalue>jsonb
</returnvalue>
15852 Builds a JSON object out of a text array. The array must have either
15853 exactly one dimension with an even number of members, in which case
15854 they are taken as alternating key/value pairs, or two dimensions
15855 such that each inner array has exactly two elements, which
15856 are taken as a key/value pair. All values are converted to JSON
15860 <literal>json_object('{a,
1, b,
"def", c,
3.5}')
</literal>
15861 <returnvalue>{
"a" :
"1",
"b" :
"def",
"c" :
"3.5"}
</returnvalue>
15863 <para><literal>json_object('{{a,
1}, {b,
"def"}, {c,
3.5}}')
</literal>
15864 <returnvalue>{
"a" :
"1",
"b" :
"def",
"c" :
"3.5"}
</returnvalue>
15869 <entry role=
"func_table_entry"><para role=
"func_signature">
15870 <function>json_object
</function> (
<parameter>keys
</parameter> <type>text[]
</type>,
<parameter>values
</parameter> <type>text[]
</type> )
15871 <returnvalue>json
</returnvalue>
15873 <para role=
"func_signature">
15874 <function>jsonb_object
</function> (
<parameter>keys
</parameter> <type>text[]
</type>,
<parameter>values
</parameter> <type>text[]
</type> )
15875 <returnvalue>jsonb
</returnvalue>
15878 This form of
<function>json_object
</function> takes keys and values
15879 pairwise from separate text arrays. Otherwise it is identical to
15880 the one-argument form.
15883 <literal>json_object('{a,b}', '{
1,
2}')
</literal>
15884 <returnvalue>{
"a":
"1",
"b":
"2"}
</returnvalue>
15892 <xref linkend=
"functions-json-processing-table"/> shows the functions that
15893 are available for processing
<type>json
</type> and
<type>jsonb
</type> values.
15896 <table id=
"functions-json-processing-table">
15897 <title>JSON Processing Functions
</title>
15901 <entry role=
"func_table_entry"><para role=
"func_signature">
15915 <entry role=
"func_table_entry"><para role=
"func_signature">
15917 <primary>json_array_elements
</primary>
15919 <function>json_array_elements
</function> (
<type>json
</type> )
15920 <returnvalue>setof json
</returnvalue>
15922 <para role=
"func_signature">
15924 <primary>jsonb_array_elements
</primary>
15926 <function>jsonb_array_elements
</function> (
<type>jsonb
</type> )
15927 <returnvalue>setof jsonb
</returnvalue>
15930 Expands the top-level JSON array into a set of JSON values.
15933 <literal>select * from json_array_elements('[
1,true, [
2,false]]')
</literal>
15934 <returnvalue></returnvalue>
15946 <entry role=
"func_table_entry"><para role=
"func_signature">
15948 <primary>json_array_elements_text
</primary>
15950 <function>json_array_elements_text
</function> (
<type>json
</type> )
15951 <returnvalue>setof text
</returnvalue>
15953 <para role=
"func_signature">
15955 <primary>jsonb_array_elements_text
</primary>
15957 <function>jsonb_array_elements_text
</function> (
<type>jsonb
</type> )
15958 <returnvalue>setof text
</returnvalue>
15961 Expands the top-level JSON array into a set of
<type>text
</type> values.
15964 <literal>select * from json_array_elements_text('[
"foo",
"bar"]')
</literal>
15965 <returnvalue></returnvalue>
15976 <entry role=
"func_table_entry"><para role=
"func_signature">
15978 <primary>json_array_length
</primary>
15980 <function>json_array_length
</function> (
<type>json
</type> )
15981 <returnvalue>integer
</returnvalue>
15983 <para role=
"func_signature">
15985 <primary>jsonb_array_length
</primary>
15987 <function>jsonb_array_length
</function> (
<type>jsonb
</type> )
15988 <returnvalue>integer
</returnvalue>
15991 Returns the number of elements in the top-level JSON array.
15994 <literal>json_array_length('[
1,
2,
3,{
"f1":
1,
"f2":[
5,
6]},
4]')
</literal>
15995 <returnvalue>5</returnvalue>
15998 <literal>jsonb_array_length('[]')
</literal>
15999 <returnvalue>0</returnvalue>
16004 <entry role=
"func_table_entry"><para role=
"func_signature">
16006 <primary>json_each
</primary>
16008 <function>json_each
</function> (
<type>json
</type> )
16009 <returnvalue>setof record
</returnvalue>
16010 (
<parameter>key
</parameter> <type>text
</type>,
16011 <parameter>value
</parameter> <type>json
</type> )
16013 <para role=
"func_signature">
16015 <primary>jsonb_each
</primary>
16017 <function>jsonb_each
</function> (
<type>jsonb
</type> )
16018 <returnvalue>setof record
</returnvalue>
16019 (
<parameter>key
</parameter> <type>text
</type>,
16020 <parameter>value
</parameter> <type>jsonb
</type> )
16023 Expands the top-level JSON object into a set of key/value pairs.
16026 <literal>select * from json_each('{
"a":
"foo",
"b":
"bar"}')
</literal>
16027 <returnvalue></returnvalue>
16038 <entry role=
"func_table_entry"><para role=
"func_signature">
16040 <primary>json_each_text
</primary>
16042 <function>json_each_text
</function> (
<type>json
</type> )
16043 <returnvalue>setof record
</returnvalue>
16044 (
<parameter>key
</parameter> <type>text
</type>,
16045 <parameter>value
</parameter> <type>text
</type> )
16047 <para role=
"func_signature">
16049 <primary>jsonb_each_text
</primary>
16051 <function>jsonb_each_text
</function> (
<type>jsonb
</type> )
16052 <returnvalue>setof record
</returnvalue>
16053 (
<parameter>key
</parameter> <type>text
</type>,
16054 <parameter>value
</parameter> <type>text
</type> )
16057 Expands the top-level JSON object into a set of key/value pairs.
16058 The returned
<parameter>value
</parameter>s will be of
16059 type
<type>text
</type>.
16062 <literal>select * from json_each_text('{
"a":
"foo",
"b":
"bar"}')
</literal>
16063 <returnvalue></returnvalue>
16074 <entry role=
"func_table_entry"><para role=
"func_signature">
16076 <primary>json_extract_path
</primary>
16078 <function>json_extract_path
</function> (
<parameter>from_json
</parameter> <type>json
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16079 <returnvalue>json
</returnvalue>
16081 <para role=
"func_signature">
16083 <primary>jsonb_extract_path
</primary>
16085 <function>jsonb_extract_path
</function> (
<parameter>from_json
</parameter> <type>jsonb
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16086 <returnvalue>jsonb
</returnvalue>
16089 Extracts JSON sub-object at the specified path.
16090 (This is functionally equivalent to the
<literal>#
></literal>
16091 operator, but writing the path out as a variadic list can be more
16092 convenient in some cases.)
16095 <literal>json_extract_path('{
"f2":{
"f3":
1},
"f4":{
"f5":
99,
"f6":
"foo"}}', 'f4', 'f6')
</literal>
16096 <returnvalue>"foo"</returnvalue>
16101 <entry role=
"func_table_entry"><para role=
"func_signature">
16103 <primary>json_extract_path_text
</primary>
16105 <function>json_extract_path_text
</function> (
<parameter>from_json
</parameter> <type>json
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16106 <returnvalue>text
</returnvalue>
16108 <para role=
"func_signature">
16110 <primary>jsonb_extract_path_text
</primary>
16112 <function>jsonb_extract_path_text
</function> (
<parameter>from_json
</parameter> <type>jsonb
</type>,
<literal>VARIADIC
</literal> <parameter>path_elems
</parameter> <type>text[]
</type> )
16113 <returnvalue>text
</returnvalue>
16116 Extracts JSON sub-object at the specified path as
<type>text
</type>.
16117 (This is functionally equivalent to the
<literal>#
>></literal>
16121 <literal>json_extract_path_text('{
"f2":{
"f3":
1},
"f4":{
"f5":
99,
"f6":
"foo"}}', 'f4', 'f6')
</literal>
16122 <returnvalue>foo
</returnvalue>
16127 <entry role=
"func_table_entry"><para role=
"func_signature">
16129 <primary>json_object_keys
</primary>
16131 <function>json_object_keys
</function> (
<type>json
</type> )
16132 <returnvalue>setof text
</returnvalue>
16134 <para role=
"func_signature">
16136 <primary>jsonb_object_keys
</primary>
16138 <function>jsonb_object_keys
</function> (
<type>jsonb
</type> )
16139 <returnvalue>setof text
</returnvalue>
16142 Returns the set of keys in the top-level JSON object.
16145 <literal>select * from json_object_keys('{
"f1":
"abc",
"f2":{
"f3":
"a",
"f4":
"b"}}')
</literal>
16146 <returnvalue></returnvalue>
16157 <entry role=
"func_table_entry"><para role=
"func_signature">
16159 <primary>json_populate_record
</primary>
16161 <function>json_populate_record
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16162 <returnvalue>anyelement
</returnvalue>
16164 <para role=
"func_signature">
16166 <primary>jsonb_populate_record
</primary>
16168 <function>jsonb_populate_record
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>jsonb
</type> )
16169 <returnvalue>anyelement
</returnvalue>
16172 Expands the top-level JSON object to a row having the composite type
16173 of the
<parameter>base
</parameter> argument. The JSON object
16174 is scanned for fields whose names match column names of the output row
16175 type, and their values are inserted into those columns of the output.
16176 (Fields that do not correspond to any output column name are ignored.)
16177 In typical use, the value of
<parameter>base
</parameter> is just
16178 <literal>NULL
</literal>, which means that any output columns that do
16179 not match any object field will be filled with nulls. However,
16180 if
<parameter>base
</parameter> isn't
<literal>NULL
</literal> then
16181 the values it contains will be used for unmatched columns.
16184 To convert a JSON value to the SQL type of an output column, the
16185 following rules are applied in sequence:
16186 <itemizedlist spacing=
"compact">
16189 A JSON null value is converted to an SQL null in all cases.
16194 If the output column is of type
<type>json
</type>
16195 or
<type>jsonb
</type>, the JSON value is just reproduced exactly.
16200 If the output column is a composite (row) type, and the JSON value
16201 is a JSON object, the fields of the object are converted to columns
16202 of the output row type by recursive application of these rules.
16207 Likewise, if the output column is an array type and the JSON value
16208 is a JSON array, the elements of the JSON array are converted to
16209 elements of the output array by recursive application of these
16215 Otherwise, if the JSON value is a string, the contents of the
16216 string are fed to the input conversion function for the column's
16222 Otherwise, the ordinary text representation of the JSON value is
16223 fed to the input conversion function for the column's data type.
16229 While the example below uses a constant JSON value, typical use would
16230 be to reference a
<type>json
</type> or
<type>jsonb
</type> column
16231 laterally from another table in the query's
<literal>FROM
</literal>
16232 clause. Writing
<function>json_populate_record
</function> in
16233 the
<literal>FROM
</literal> clause is good practice, since all of the
16234 extracted columns are available for use without duplicate function
16238 <literal>create type subrowtype as (d int, e text);
</literal>
16239 <literal>create type myrowtype as (a int, b text[], c subrowtype);
</literal>
16242 <literal>select * from json_populate_record(null::myrowtype,
16243 '{
"a":
1,
"b": [
"2",
"a b"],
"c": {
"d":
4,
"e":
"a b c"},
"x":
"foo"}')
</literal>
16244 <returnvalue></returnvalue>
16247 ---+-----------+-------------
16248 1 | {
2,
"a b"} | (
4,
"a b c")
16254 <entry role=
"func_table_entry"><para role=
"func_signature">
16256 <primary>json_populate_recordset
</primary>
16258 <function>json_populate_recordset
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>json
</type> )
16259 <returnvalue>setof anyelement
</returnvalue>
16261 <para role=
"func_signature">
16263 <primary>jsonb_populate_recordset
</primary>
16265 <function>jsonb_populate_recordset
</function> (
<parameter>base
</parameter> <type>anyelement
</type>,
<parameter>from_json
</parameter> <type>jsonb
</type> )
16266 <returnvalue>setof anyelement
</returnvalue>
16269 Expands the top-level JSON array of objects to a set of rows having
16270 the composite type of the
<parameter>base
</parameter> argument.
16271 Each element of the JSON array is processed as described above
16272 for
<function>json[b]_populate_record
</function>.
16275 <literal>create type twoints as (a int, b int);
</literal>
16278 <literal>select * from json_populate_recordset(null::twoints, '[{
"a":
1,
"b":
2}, {
"a":
3,
"b":
4}]')
</literal>
16279 <returnvalue></returnvalue>
16290 <entry role=
"func_table_entry"><para role=
"func_signature">
16292 <primary>json_to_record
</primary>
16294 <function>json_to_record
</function> (
<type>json
</type> )
16295 <returnvalue>record
</returnvalue>
16297 <para role=
"func_signature">
16299 <primary>jsonb_to_record
</primary>
16301 <function>jsonb_to_record
</function> (
<type>jsonb
</type> )
16302 <returnvalue>record
</returnvalue>
16305 Expands the top-level JSON object to a row having the composite type
16306 defined by an
<literal>AS
</literal> clause. (As with all functions
16307 returning
<type>record
</type>, the calling query must explicitly
16308 define the structure of the record with an
<literal>AS
</literal>
16309 clause.) The output record is filled from fields of the JSON object,
16310 in the same way as described above
16311 for
<function>json[b]_populate_record
</function>. Since there is no
16312 input record value, unmatched columns are always filled with nulls.
16315 <literal>create type myrowtype as (a int, b text);
</literal>
16318 <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>
16319 <returnvalue></returnvalue>
16322 ---+---------+---------+---+---------------
16323 1 | [
1,
2,
3] | {
1,
2,
3} | | (
123,
"a b c")
16329 <entry role=
"func_table_entry"><para role=
"func_signature">
16331 <primary>json_to_recordset
</primary>
16333 <function>json_to_recordset
</function> (
<type>json
</type> )
16334 <returnvalue>setof record
</returnvalue>
16336 <para role=
"func_signature">
16338 <primary>jsonb_to_recordset
</primary>
16340 <function>jsonb_to_recordset
</function> (
<type>jsonb
</type> )
16341 <returnvalue>setof record
</returnvalue>
16344 Expands the top-level JSON array of objects to a set of rows having
16345 the composite type defined by an
<literal>AS
</literal> clause. (As
16346 with all functions returning
<type>record
</type>, the calling query
16347 must explicitly define the structure of the record with
16348 an
<literal>AS
</literal> clause.) Each element of the JSON array is
16349 processed as described above
16350 for
<function>json[b]_populate_record
</function>.
16353 <literal>select * from json_to_recordset('[{
"a":
1,
"b":
"foo"}, {
"a":
"2",
"c":
"bar"}]') as x(a int, b text)
</literal>
16354 <returnvalue></returnvalue>
16365 <entry role=
"func_table_entry"><para role=
"func_signature">
16367 <primary>jsonb_set
</primary>
16369 <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> )
16370 <returnvalue>jsonb
</returnvalue>
16373 Returns
<parameter>target
</parameter>
16374 with the item designated by
<parameter>path
</parameter>
16375 replaced by
<parameter>new_value
</parameter>, or with
16376 <parameter>new_value
</parameter> added if
16377 <parameter>create_if_missing
</parameter> is true (which is the
16378 default) and the item designated by
<parameter>path
</parameter>
16380 All earlier steps in the path must exist, or
16381 the
<parameter>target
</parameter> is returned unchanged.
16382 As with the path oriented operators, negative integers that
16383 appear in the
<parameter>path
</parameter> count from the end
16385 If the last path step is an array index that is out of range,
16386 and
<parameter>create_if_missing
</parameter> is true, the new
16387 value is added at the beginning of the array if the index is negative,
16388 or at the end of the array if it is positive.
16391 <literal>jsonb_set('[{
"f1":
1,
"f2":null},
2,null,
3]', '{
0,f1}', '[
2,
3,
4]', false)
</literal>
16392 <returnvalue>[{
"f1": [
2,
3,
4],
"f2": null},
2, null,
3]
</returnvalue>
16395 <literal>jsonb_set('[{
"f1":
1,
"f2":null},
2]', '{
0,f3}', '[
2,
3,
4]')
</literal>
16396 <returnvalue>[{
"f1":
1,
"f2": null,
"f3": [
2,
3,
4]},
2]
</returnvalue>
16401 <entry role=
"func_table_entry"><para role=
"func_signature">
16403 <primary>jsonb_set_lax
</primary>
16405 <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> )
16406 <returnvalue>jsonb
</returnvalue>
16409 If
<parameter>new_value
</parameter> is not
<literal>NULL
</literal>,
16410 behaves identically to
<literal>jsonb_set
</literal>. Otherwise behaves
16411 according to the value
16412 of
<parameter>null_value_treatment
</parameter> which must be one
16413 of
<literal>'raise_exception'
</literal>,
16414 <literal>'use_json_null'
</literal>,
<literal>'delete_key'
</literal>, or
16415 <literal>'return_target'
</literal>. The default is
16416 <literal>'use_json_null'
</literal>.
16419 <literal>jsonb_set_lax('[{
"f1":
1,
"f2":null},
2,null,
3]', '{
0,f1}', null)
</literal>
16420 <returnvalue>[{
"f1": null,
"f2": null},
2, null,
3]
</returnvalue>
16423 <literal>jsonb_set_lax('[{
"f1":
99,
"f2":null},
2]', '{
0,f3}', null, true, 'return_target')
</literal>
16424 <returnvalue>[{
"f1":
99,
"f2": null},
2]
</returnvalue>
16429 <entry role=
"func_table_entry"><para role=
"func_signature">
16431 <primary>jsonb_insert
</primary>
16433 <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> )
16434 <returnvalue>jsonb
</returnvalue>
16437 Returns
<parameter>target
</parameter>
16438 with
<parameter>new_value
</parameter> inserted. If the item
16439 designated by the
<parameter>path
</parameter> is an array
16440 element,
<parameter>new_value
</parameter> will be inserted before
16441 that item if
<parameter>insert_after
</parameter> is false (which
16442 is the default), or after it
16443 if
<parameter>insert_after
</parameter> is true. If the item
16444 designated by the
<parameter>path
</parameter> is an object
16445 field,
<parameter>new_value
</parameter> will be inserted only if
16446 the object does not already contain that key.
16447 All earlier steps in the path must exist, or
16448 the
<parameter>target
</parameter> is returned unchanged.
16449 As with the path oriented operators, negative integers that
16450 appear in the
<parameter>path
</parameter> count from the end
16452 If the last path step is an array index that is out of range, the new
16453 value is added at the beginning of the array if the index is negative,
16454 or at the end of the array if it is positive.
16457 <literal>jsonb_insert('{
"a": [
0,
1,
2]}', '{a,
1}', '
"new_value"')
</literal>
16458 <returnvalue>{
"a": [
0,
"new_value",
1,
2]}
</returnvalue>
16461 <literal>jsonb_insert('{
"a": [
0,
1,
2]}', '{a,
1}', '
"new_value"', true)
</literal>
16462 <returnvalue>{
"a": [
0,
1,
"new_value",
2]}
</returnvalue>
16467 <entry role=
"func_table_entry"><para role=
"func_signature">
16469 <primary>json_strip_nulls
</primary>
16471 <function>json_strip_nulls
</function> (
<type>json
</type> )
16472 <returnvalue>json
</returnvalue>
16474 <para role=
"func_signature">
16476 <primary>jsonb_strip_nulls
</primary>
16478 <function>jsonb_strip_nulls
</function> (
<type>jsonb
</type> )
16479 <returnvalue>jsonb
</returnvalue>
16482 Deletes all object fields that have null values from the given JSON
16483 value, recursively. Null values that are not object fields are
16487 <literal>json_strip_nulls('[{
"f1":
1,
"f2":null},
2, null,
3]')
</literal>
16488 <returnvalue>[{
"f1":
1},
2,null,
3]
</returnvalue>
16493 <entry role=
"func_table_entry"><para role=
"func_signature">
16495 <primary>jsonb_path_exists
</primary>
16497 <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> )
16498 <returnvalue>boolean
</returnvalue>
16501 Checks whether the JSON path returns any item for the specified JSON
16503 If the
<parameter>vars
</parameter> argument is specified, it must
16504 be a JSON object, and its fields provide named values to be
16505 substituted into the
<type>jsonpath
</type> expression.
16506 If the
<parameter>silent
</parameter> argument is specified and
16507 is
<literal>true
</literal>, the function suppresses the same errors
16508 as the
<literal>@?
</literal> and
<literal>@@
</literal> operators do.
16511 <literal>jsonb_path_exists('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
16512 <returnvalue>t
</returnvalue>
16517 <entry role=
"func_table_entry"><para role=
"func_signature">
16519 <primary>jsonb_path_match
</primary>
16521 <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> )
16522 <returnvalue>boolean
</returnvalue>
16525 Returns the result of a JSON path predicate check for the specified
16526 JSON value. Only the first item of the result is taken into account.
16527 If the result is not Boolean, then
<literal>NULL
</literal> is returned.
16528 The optional
<parameter>vars
</parameter>
16529 and
<parameter>silent
</parameter> arguments act the same as
16530 for
<function>jsonb_path_exists
</function>.
16533 <literal>jsonb_path_match('{
"a":[
1,
2,
3,
4,
5]}', 'exists($.a[*] ? (@
>= $min
&& @
<= $max))', '{
"min":
2,
"max":
4}')
</literal>
16534 <returnvalue>t
</returnvalue>
16539 <entry role=
"func_table_entry"><para role=
"func_signature">
16541 <primary>jsonb_path_query
</primary>
16543 <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> )
16544 <returnvalue>setof jsonb
</returnvalue>
16547 Returns all JSON items returned by the JSON path for the specified
16549 The optional
<parameter>vars
</parameter>
16550 and
<parameter>silent
</parameter> arguments act the same as
16551 for
<function>jsonb_path_exists
</function>.
16554 <literal>select * from jsonb_path_query('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
16555 <returnvalue></returnvalue>
16567 <entry role=
"func_table_entry"><para role=
"func_signature">
16569 <primary>jsonb_path_query_array
</primary>
16571 <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> )
16572 <returnvalue>jsonb
</returnvalue>
16575 Returns all JSON items returned by the JSON path for the specified
16576 JSON value, as a JSON array.
16577 The optional
<parameter>vars
</parameter>
16578 and
<parameter>silent
</parameter> arguments act the same as
16579 for
<function>jsonb_path_exists
</function>.
16582 <literal>jsonb_path_query_array('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
16583 <returnvalue>[
2,
3,
4]
</returnvalue>
16588 <entry role=
"func_table_entry"><para role=
"func_signature">
16590 <primary>jsonb_path_query_first
</primary>
16592 <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> )
16593 <returnvalue>jsonb
</returnvalue>
16596 Returns the first JSON item returned by the JSON path for the
16597 specified JSON value. Returns
<literal>NULL
</literal> if there are no
16599 The optional
<parameter>vars
</parameter>
16600 and
<parameter>silent
</parameter> arguments act the same as
16601 for
<function>jsonb_path_exists
</function>.
16604 <literal>jsonb_path_query_first('{
"a":[
1,
2,
3,
4,
5]}', '$.a[*] ? (@
>= $min
&& @
<= $max)', '{
"min":
2,
"max":
4}')
</literal>
16605 <returnvalue>2</returnvalue>
16610 <entry role=
"func_table_entry"><para role=
"func_signature">
16612 <primary>jsonb_path_exists_tz
</primary>
16614 <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> )
16615 <returnvalue>boolean
</returnvalue>
16617 <para role=
"func_signature">
16619 <primary>jsonb_path_match_tz
</primary>
16621 <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> )
16622 <returnvalue>boolean
</returnvalue>
16624 <para role=
"func_signature">
16626 <primary>jsonb_path_query_tz
</primary>
16628 <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> )
16629 <returnvalue>setof jsonb
</returnvalue>
16631 <para role=
"func_signature">
16633 <primary>jsonb_path_query_array_tz
</primary>
16635 <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> )
16636 <returnvalue>jsonb
</returnvalue>
16638 <para role=
"func_signature">
16640 <primary>jsonb_path_query_first_tz
</primary>
16642 <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> )
16643 <returnvalue>jsonb
</returnvalue>
16646 These functions act like their counterparts described above without
16647 the
<literal>_tz
</literal> suffix, except that these functions support
16648 comparisons of date/time values that require timezone-aware
16649 conversions. The example below requires interpretation of the
16650 date-only value
<literal>2015-
08-
02</literal> as a timestamp with time
16651 zone, so the result depends on the current
16652 <xref linkend=
"guc-timezone"/> setting. Due to this dependency, these
16653 functions are marked as stable, which means these functions cannot be
16654 used in indexes. Their counterparts are immutable, and so can be used
16655 in indexes; but they will throw errors if asked to make such
16659 <literal>jsonb_path_exists_tz('[
"2015-08-01 12:00:00-05"]', '$[*] ? (@.datetime()
< "2015-08-02".datetime())')
</literal>
16660 <returnvalue>t
</returnvalue>
16665 <entry role=
"func_table_entry"><para role=
"func_signature">
16667 <primary>jsonb_pretty
</primary>
16669 <function>jsonb_pretty
</function> (
<type>jsonb
</type> )
16670 <returnvalue>text
</returnvalue>
16673 Converts the given JSON value to pretty-printed, indented text.
16676 <literal>jsonb_pretty('[{
"f1":
1,
"f2":null},
2]')
</literal>
16677 <returnvalue></returnvalue>
16691 <entry role=
"func_table_entry"><para role=
"func_signature">
16693 <primary>json_typeof
</primary>
16695 <function>json_typeof
</function> (
<type>json
</type> )
16696 <returnvalue>text
</returnvalue>
16698 <para role=
"func_signature">
16700 <primary>jsonb_typeof
</primary>
16702 <function>jsonb_typeof
</function> (
<type>jsonb
</type> )
16703 <returnvalue>text
</returnvalue>
16706 Returns the type of the top-level JSON value as a text string.
16708 <literal>object
</literal>,
<literal>array
</literal>,
16709 <literal>string
</literal>,
<literal>number
</literal>,
16710 <literal>boolean
</literal>, and
<literal>null
</literal>.
16711 (The
<literal>null
</literal> result should not be confused
16712 with an SQL NULL; see the examples.)
16715 <literal>json_typeof('-
123.4')
</literal>
16716 <returnvalue>number
</returnvalue>
16719 <literal>json_typeof('null'::json)
</literal>
16720 <returnvalue>null
</returnvalue>
16723 <literal>json_typeof(NULL::json) IS NULL
</literal>
16724 <returnvalue>t
</returnvalue>
16732 <sect2 id=
"functions-sqljson-path">
16733 <title>The SQL/JSON Path Language
</title>
16735 <indexterm zone=
"functions-sqljson-path">
16736 <primary>SQL/JSON path language
</primary>
16740 SQL/JSON path expressions specify the items to be retrieved
16741 from the JSON data, similar to XPath expressions used
16742 for SQL access to XML. In
<productname>PostgreSQL
</productname>,
16743 path expressions are implemented as the
<type>jsonpath
</type>
16744 data type and can use any elements described in
16745 <xref linkend=
"datatype-jsonpath"/>.
16749 JSON query functions and operators
16750 pass the provided path expression to the
<firstterm>path engine
</firstterm>
16751 for evaluation. If the expression matches the queried JSON data,
16752 the corresponding JSON item, or set of items, is returned.
16753 Path expressions are written in the SQL/JSON path language
16754 and can include arithmetic expressions and functions.
16758 A path expression consists of a sequence of elements allowed
16759 by the
<type>jsonpath
</type> data type.
16760 The path expression is normally evaluated from left to right, but
16761 you can use parentheses to change the order of operations.
16762 If the evaluation is successful, a sequence of JSON items is produced,
16763 and the evaluation result is returned to the JSON query function
16764 that completes the specified computation.
16768 To refer to the JSON value being queried (the
16769 <firstterm>context item
</firstterm>), use the
<literal>$
</literal> variable
16770 in the path expression. It can be followed by one or more
16771 <link linkend=
"type-jsonpath-accessors">accessor operators
</link>,
16772 which go down the JSON structure level by level to retrieve sub-items
16773 of the context item. Each operator that follows deals with the
16774 result of the previous evaluation step.
16778 For example, suppose you have some JSON data from a GPS tracker that you
16779 would like to parse, such as:
16785 "location": [
47.763,
13.4034 ],
16786 "start time":
"2018-10-14 10:05:14",
16790 "location": [
47.706,
13.2635 ],
16791 "start time":
"2018-10-14 10:39:21",
16801 To retrieve the available track segments, you need to use the
16802 <literal>.
<replaceable>key
</replaceable></literal> accessor
16803 operator to descend through surrounding JSON objects:
16810 To retrieve the contents of an array, you typically use the
16811 <literal>[*]
</literal> operator. For example,
16812 the following path will return the location coordinates for all
16813 the available track segments:
16815 $.track.segments[*].location
16820 To return the coordinates of the first segment only, you can
16821 specify the corresponding subscript in the
<literal>[]
</literal>
16822 accessor operator. Recall that JSON array indexes are
0-relative:
16824 $.track.segments[
0].location
16829 The result of each path evaluation step can be processed
16830 by one or more
<type>jsonpath
</type> operators and methods
16831 listed in
<xref linkend=
"functions-sqljson-path-operators"/>.
16832 Each method name must be preceded by a dot. For example,
16833 you can get the size of an array:
16835 $.track.segments.size()
16837 More examples of using
<type>jsonpath
</type> operators
16838 and methods within path expressions appear below in
16839 <xref linkend=
"functions-sqljson-path-operators"/>.
16843 When defining a path, you can also use one or more
16844 <firstterm>filter expressions
</firstterm> that work similarly to the
16845 <literal>WHERE
</literal> clause in SQL. A filter expression begins with
16846 a question mark and provides a condition in parentheses:
16849 ? (
<replaceable>condition
</replaceable>)
16854 Filter expressions must be written just after the path evaluation step
16855 to which they should apply. The result of that step is filtered to include
16856 only those items that satisfy the provided condition. SQL/JSON defines
16857 three-valued logic, so the condition can be
<literal>true
</literal>,
<literal>false
</literal>,
16858 or
<literal>unknown
</literal>. The
<literal>unknown
</literal> value
16859 plays the same role as SQL
<literal>NULL
</literal> and can be tested
16860 for with the
<literal>is unknown
</literal> predicate. Further path
16861 evaluation steps use only those items for which the filter expression
16862 returned
<literal>true
</literal>.
16866 The functions and operators that can be used in filter expressions are
16867 listed in
<xref linkend=
"functions-sqljson-filter-ex-table"/>. Within a
16868 filter expression, the
<literal>@
</literal> variable denotes the value
16869 being filtered (i.e., one result of the preceding path step). You can
16870 write accessor operators after
<literal>@
</literal> to retrieve component
16875 For example, suppose you would like to retrieve all heart rate values higher
16876 than
130. You can achieve this using the following expression:
16878 $.track.segments[*].HR ? (@
> 130)
16883 To get the start times of segments with such values, you have to
16884 filter out irrelevant segments before returning the start times, so the
16885 filter expression is applied to the previous step, and the path used
16886 in the condition is different:
16888 $.track.segments[*] ? (@.HR
> 130).
"start time"
16893 You can use several filter expressions in sequence, if required. For
16894 example, the following expression selects start times of all segments that
16895 contain locations with relevant coordinates and high heart rate values:
16897 $.track.segments[*] ? (@.location[
1]
< 13.4) ? (@.HR
> 130).
"start time"
16902 Using filter expressions at different nesting levels is also allowed.
16903 The following example first filters all segments by location, and then
16904 returns high heart rate values for these segments, if available:
16906 $.track.segments[*] ? (@.location[
1]
< 13.4).HR ? (@
> 130)
16911 You can also nest filter expressions within each other:
16913 $.track ? (exists(@.segments[*] ? (@.HR
> 130))).segments.size()
16915 This expression returns the size of the track if it contains any
16916 segments with high heart rate values, or an empty sequence otherwise.
16920 <productname>PostgreSQL
</productname>'s implementation of the SQL/JSON path
16921 language has the following deviations from the SQL/JSON standard:
16927 A path expression can be a Boolean predicate, although the SQL/JSON
16928 standard allows predicates only in filters. This is necessary for
16929 implementation of the
<literal>@@
</literal> operator. For example,
16930 the following
<type>jsonpath
</type> expression is valid in
16931 <productname>PostgreSQL
</productname>:
16933 $.track.segments[*].HR
< 70
16940 There are minor differences in the interpretation of regular
16941 expression patterns used in
<literal>like_regex
</literal> filters, as
16942 described in
<xref linkend=
"jsonpath-regular-expressions"/>.
16947 <sect3 id=
"strict-and-lax-modes">
16948 <title>Strict and Lax Modes
</title>
16950 When you query JSON data, the path expression may not match the
16951 actual JSON data structure. An attempt to access a non-existent
16952 member of an object or element of an array results in a
16953 structural error. SQL/JSON path expressions have two modes
16954 of handling structural errors:
16960 lax (default)
— the path engine implicitly adapts
16961 the queried data to the specified path.
16962 Any remaining structural errors are suppressed and converted
16963 to empty SQL/JSON sequences.
16968 strict
— if a structural error occurs, an error is raised.
16974 The lax mode facilitates matching of a JSON document structure and path
16975 expression if the JSON data does not conform to the expected schema.
16976 If an operand does not match the requirements of a particular operation,
16977 it can be automatically wrapped as an SQL/JSON array or unwrapped by
16978 converting its elements into an SQL/JSON sequence before performing
16979 this operation. Besides, comparison operators automatically unwrap their
16980 operands in the lax mode, so you can compare SQL/JSON arrays
16981 out-of-the-box. An array of size
1 is considered equal to its sole element.
16982 Automatic unwrapping is not performed only when:
16986 The path expression contains
<literal>type()
</literal> or
16987 <literal>size()
</literal> methods that return the type
16988 and the number of elements in the array, respectively.
16993 The queried JSON data contain nested arrays. In this case, only
16994 the outermost array is unwrapped, while all the inner arrays
16995 remain unchanged. Thus, implicit unwrapping can only go one
16996 level down within each path evaluation step.
17003 For example, when querying the GPS data listed above, you can
17004 abstract from the fact that it stores an array of segments
17005 when using the lax mode:
17007 lax $.track.segments.location
17012 In the strict mode, the specified path must exactly match the structure of
17013 the queried JSON document to return an SQL/JSON item, so using this
17014 path expression will cause an error. To get the same result as in
17015 the lax mode, you have to explicitly unwrap the
17016 <literal>segments
</literal> array:
17018 strict $.track.segments[*].location
17023 The
<literal>.**
</literal> accessor can lead to surprising results
17024 when using the lax mode. For instance, the following query selects every
17025 <literal>HR
</literal> value twice:
17029 This happens because the
<literal>.**
</literal> accessor selects both
17030 the
<literal>segments
</literal> array and each of its elements, while
17031 the
<literal>.HR
</literal> accessor automatically unwraps arrays when
17032 using the lax mode. To avoid surprising results, we recommend using
17033 the
<literal>.**
</literal> accessor only in the strict mode. The
17034 following query selects each
<literal>HR
</literal> value just once:
17042 <sect3 id=
"functions-sqljson-path-operators">
17043 <title>SQL/JSON Path Operators and Methods
</title>
17046 <xref linkend=
"functions-sqljson-op-table"/> shows the operators and
17047 methods available in
<type>jsonpath
</type>. Note that while the unary
17048 operators and methods can be applied to multiple values resulting from a
17049 preceding path step, the binary operators (addition etc.) can only be
17050 applied to single values.
17053 <table id=
"functions-sqljson-op-table">
17054 <title><type>jsonpath
</type> Operators and Methods
</title>
17058 <entry role=
"func_table_entry"><para role=
"func_signature">
17072 <entry role=
"func_table_entry"><para role=
"func_signature">
17073 <replaceable>number
</replaceable> <literal>+
</literal> <replaceable>number
</replaceable>
17074 <returnvalue><replaceable>number
</replaceable></returnvalue>
17080 <literal>jsonb_path_query('[
2]', '$[
0] +
3')
</literal>
17081 <returnvalue>5</returnvalue>
17086 <entry role=
"func_table_entry"><para role=
"func_signature">
17087 <literal>+
</literal> <replaceable>number
</replaceable>
17088 <returnvalue><replaceable>number
</replaceable></returnvalue>
17091 Unary plus (no operation); unlike addition, this can iterate over
17095 <literal>jsonb_path_query_array('{
"x": [
2,
3,
4]}', '+ $.x')
</literal>
17096 <returnvalue>[
2,
3,
4]
</returnvalue>
17101 <entry role=
"func_table_entry"><para role=
"func_signature">
17102 <replaceable>number
</replaceable> <literal>-
</literal> <replaceable>number
</replaceable>
17103 <returnvalue><replaceable>number
</replaceable></returnvalue>
17109 <literal>jsonb_path_query('[
2]', '
7 - $[
0]')
</literal>
17110 <returnvalue>5</returnvalue>
17115 <entry role=
"func_table_entry"><para role=
"func_signature">
17116 <literal>-
</literal> <replaceable>number
</replaceable>
17117 <returnvalue><replaceable>number
</replaceable></returnvalue>
17120 Negation; unlike subtraction, this can iterate over
17124 <literal>jsonb_path_query_array('{
"x": [
2,
3,
4]}', '- $.x')
</literal>
17125 <returnvalue>[-
2, -
3, -
4]
</returnvalue>
17130 <entry role=
"func_table_entry"><para role=
"func_signature">
17131 <replaceable>number
</replaceable> <literal>*
</literal> <replaceable>number
</replaceable>
17132 <returnvalue><replaceable>number
</replaceable></returnvalue>
17138 <literal>jsonb_path_query('[
4]', '
2 * $[
0]')
</literal>
17139 <returnvalue>8</returnvalue>
17144 <entry role=
"func_table_entry"><para role=
"func_signature">
17145 <replaceable>number
</replaceable> <literal>/
</literal> <replaceable>number
</replaceable>
17146 <returnvalue><replaceable>number
</replaceable></returnvalue>
17152 <literal>jsonb_path_query('[
8.5]', '$[
0] /
2')
</literal>
17153 <returnvalue>4.2500000000000000</returnvalue>
17158 <entry role=
"func_table_entry"><para role=
"func_signature">
17159 <replaceable>number
</replaceable> <literal>%
</literal> <replaceable>number
</replaceable>
17160 <returnvalue><replaceable>number
</replaceable></returnvalue>
17166 <literal>jsonb_path_query('[
32]', '$[
0] %
10')
</literal>
17167 <returnvalue>2</returnvalue>
17172 <entry role=
"func_table_entry"><para role=
"func_signature">
17173 <replaceable>value
</replaceable> <literal>.
</literal> <literal>type()
</literal>
17174 <returnvalue><replaceable>string
</replaceable></returnvalue>
17177 Type of the JSON item (see
<function>json_typeof
</function>)
17180 <literal>jsonb_path_query_array('[
1,
"2", {}]', '$[*].type()')
</literal>
17181 <returnvalue>[
"number",
"string",
"object"]
</returnvalue>
17186 <entry role=
"func_table_entry"><para role=
"func_signature">
17187 <replaceable>value
</replaceable> <literal>.
</literal> <literal>size()
</literal>
17188 <returnvalue><replaceable>number
</replaceable></returnvalue>
17191 Size of the JSON item (number of array elements, or
1 if not an
17195 <literal>jsonb_path_query('{
"m": [
11,
15]}', '$.m.size()')
</literal>
17196 <returnvalue>2</returnvalue>
17201 <entry role=
"func_table_entry"><para role=
"func_signature">
17202 <replaceable>value
</replaceable> <literal>.
</literal> <literal>double()
</literal>
17203 <returnvalue><replaceable>number
</replaceable></returnvalue>
17206 Approximate floating-point number converted from a JSON number or
17210 <literal>jsonb_path_query('{
"len":
"1.9"}', '$.len.double() *
2')
</literal>
17211 <returnvalue>3.8</returnvalue>
17216 <entry role=
"func_table_entry"><para role=
"func_signature">
17217 <replaceable>number
</replaceable> <literal>.
</literal> <literal>ceiling()
</literal>
17218 <returnvalue><replaceable>number
</replaceable></returnvalue>
17221 Nearest integer greater than or equal to the given number
17224 <literal>jsonb_path_query('{
"h":
1.3}', '$.h.ceiling()')
</literal>
17225 <returnvalue>2</returnvalue>
17230 <entry role=
"func_table_entry"><para role=
"func_signature">
17231 <replaceable>number
</replaceable> <literal>.
</literal> <literal>floor()
</literal>
17232 <returnvalue><replaceable>number
</replaceable></returnvalue>
17235 Nearest integer less than or equal to the given number
17238 <literal>jsonb_path_query('{
"h":
1.7}', '$.h.floor()')
</literal>
17239 <returnvalue>1</returnvalue>
17244 <entry role=
"func_table_entry"><para role=
"func_signature">
17245 <replaceable>number
</replaceable> <literal>.
</literal> <literal>abs()
</literal>
17246 <returnvalue><replaceable>number
</replaceable></returnvalue>
17249 Absolute value of the given number
17252 <literal>jsonb_path_query('{
"z": -
0.3}', '$.z.abs()')
</literal>
17253 <returnvalue>0.3</returnvalue>
17258 <entry role=
"func_table_entry"><para role=
"func_signature">
17259 <replaceable>string
</replaceable> <literal>.
</literal> <literal>datetime()
</literal>
17260 <returnvalue><replaceable>datetime_type
</replaceable></returnvalue>
17264 Date/time value converted from a string
17267 <literal>jsonb_path_query('[
"2015-8-1",
"2015-08-12"]', '$[*] ? (@.datetime()
< "2015-08-2".datetime())')
</literal>
17268 <returnvalue>"2015-8-1"</returnvalue>
17273 <entry role=
"func_table_entry"><para role=
"func_signature">
17274 <replaceable>string
</replaceable> <literal>.
</literal> <literal>datetime(
<replaceable>template
</replaceable>)
</literal>
17275 <returnvalue><replaceable>datetime_type
</replaceable></returnvalue>
17279 Date/time value converted from a string using the
17280 specified
<function>to_timestamp
</function> template
17283 <literal>jsonb_path_query_array('[
"12:30",
"18:40"]', '$[*].datetime(
"HH24:MI")')
</literal>
17284 <returnvalue>[
"12:30:00",
"18:40:00"]
</returnvalue>
17289 <entry role=
"func_table_entry"><para role=
"func_signature">
17290 <replaceable>object
</replaceable> <literal>.
</literal> <literal>keyvalue()
</literal>
17291 <returnvalue><replaceable>array
</replaceable></returnvalue>
17294 The object's key-value pairs, represented as an array of objects
17295 containing three fields:
<literal>"key"</literal>,
17296 <literal>"value"</literal>, and
<literal>"id"</literal>;
17297 <literal>"id"</literal> is a unique identifier of the object the
17298 key-value pair belongs to
17301 <literal>jsonb_path_query_array('{
"x":
"20",
"y":
32}', '$.keyvalue()')
</literal>
17302 <returnvalue>[{
"id":
0,
"key":
"x",
"value":
"20"}, {
"id":
0,
"key":
"y",
"value":
32}]
</returnvalue>
17311 The result type of the
<literal>datetime()
</literal> and
17312 <literal>datetime(
<replaceable>template
</replaceable>)
</literal>
17313 methods can be
<type>date
</type>,
<type>timetz
</type>,
<type>time
</type>,
17314 <type>timestamptz
</type>, or
<type>timestamp
</type>.
17315 Both methods determine their result type dynamically.
17318 The
<literal>datetime()
</literal> method sequentially tries to
17319 match its input string to the ISO formats
17320 for
<type>date
</type>,
<type>timetz
</type>,
<type>time
</type>,
17321 <type>timestamptz
</type>, and
<type>timestamp
</type>. It stops on
17322 the first matching format and emits the corresponding data type.
17325 The
<literal>datetime(
<replaceable>template
</replaceable>)
</literal>
17326 method determines the result type according to the fields used in the
17327 provided template string.
17330 The
<literal>datetime()
</literal> and
17331 <literal>datetime(
<replaceable>template
</replaceable>)
</literal> methods
17332 use the same parsing rules as the
<literal>to_timestamp
</literal> SQL
17333 function does (see
<xref linkend=
"functions-formatting"/>), with three
17334 exceptions. First, these methods don't allow unmatched template
17335 patterns. Second, only the following separators are allowed in the
17336 template string: minus sign, period, solidus (slash), comma, apostrophe,
17337 semicolon, colon and space. Third, separators in the template string
17338 must exactly match the input string.
17341 If different date/time types need to be compared, an implicit cast is
17342 applied. A
<type>date
</type> value can be cast to
<type>timestamp
</type>
17343 or
<type>timestamptz
</type>,
<type>timestamp
</type> can be cast to
17344 <type>timestamptz
</type>, and
<type>time
</type> to
<type>timetz
</type>.
17345 However, all but the first of these conversions depend on the current
17346 <xref linkend=
"guc-timezone"/> setting, and thus can only be performed
17347 within timezone-aware
<type>jsonpath
</type> functions.
17352 <xref linkend=
"functions-sqljson-filter-ex-table"/> shows the available
17353 filter expression elements.
17356 <table id=
"functions-sqljson-filter-ex-table">
17357 <title><type>jsonpath
</type> Filter Expression Elements
</title>
17361 <entry role=
"func_table_entry"><para role=
"func_signature">
17375 <entry role=
"func_table_entry"><para role=
"func_signature">
17376 <replaceable>value
</replaceable> <literal>==
</literal> <replaceable>value
</replaceable>
17377 <returnvalue>boolean
</returnvalue>
17380 Equality comparison (this, and the other comparison operators, work on
17381 all JSON scalar values)
17384 <literal>jsonb_path_query_array('[
1,
"a",
1,
3]', '$[*] ? (@ ==
1)')
</literal>
17385 <returnvalue>[
1,
1]
</returnvalue>
17388 <literal>jsonb_path_query_array('[
1,
"a",
1,
3]', '$[*] ? (@ ==
"a")')
</literal>
17389 <returnvalue>[
"a"]
</returnvalue>
17394 <entry role=
"func_table_entry"><para role=
"func_signature">
17395 <replaceable>value
</replaceable> <literal>!=
</literal> <replaceable>value
</replaceable>
17396 <returnvalue>boolean
</returnvalue>
17398 <para role=
"func_signature">
17399 <replaceable>value
</replaceable> <literal><></literal> <replaceable>value
</replaceable>
17400 <returnvalue>boolean
</returnvalue>
17403 Non-equality comparison
17406 <literal>jsonb_path_query_array('[
1,
2,
1,
3]', '$[*] ? (@ !=
1)')
</literal>
17407 <returnvalue>[
2,
3]
</returnvalue>
17410 <literal>jsonb_path_query_array('[
"a",
"b",
"c"]', '$[*] ? (@
<> "b")')
</literal>
17411 <returnvalue>[
"a",
"c"]
</returnvalue>
17416 <entry role=
"func_table_entry"><para role=
"func_signature">
17417 <replaceable>value
</replaceable> <literal><</literal> <replaceable>value
</replaceable>
17418 <returnvalue>boolean
</returnvalue>
17421 Less-than comparison
17424 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
< 2)')
</literal>
17425 <returnvalue>[
1]
</returnvalue>
17430 <entry role=
"func_table_entry"><para role=
"func_signature">
17431 <replaceable>value
</replaceable> <literal><=
</literal> <replaceable>value
</replaceable>
17432 <returnvalue>boolean
</returnvalue>
17435 Less-than-or-equal-to comparison
17438 <literal>jsonb_path_query_array('[
"a",
"b",
"c"]', '$[*] ? (@
<=
"b")')
</literal>
17439 <returnvalue>[
"a",
"b"]
</returnvalue>
17444 <entry role=
"func_table_entry"><para role=
"func_signature">
17445 <replaceable>value
</replaceable> <literal>></literal> <replaceable>value
</replaceable>
17446 <returnvalue>boolean
</returnvalue>
17449 Greater-than comparison
17452 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
> 2)')
</literal>
17453 <returnvalue>[
3]
</returnvalue>
17458 <entry role=
"func_table_entry"><para role=
"func_signature">
17459 <replaceable>value
</replaceable> <literal>>=
</literal> <replaceable>value
</replaceable>
17460 <returnvalue>boolean
</returnvalue>
17463 Greater-than-or-equal-to comparison
17466 <literal>jsonb_path_query_array('[
1,
2,
3]', '$[*] ? (@
>=
2)')
</literal>
17467 <returnvalue>[
2,
3]
</returnvalue>
17472 <entry role=
"func_table_entry"><para role=
"func_signature">
17473 <literal>true
</literal>
17474 <returnvalue>boolean
</returnvalue>
17477 JSON constant
<literal>true
</literal>
17480 <literal>jsonb_path_query('[{
"name":
"John",
"parent": false}, {
"name":
"Chris",
"parent": true}]', '$[*] ? (@.parent == true)')
</literal>
17481 <returnvalue>{
"name":
"Chris",
"parent": true}
</returnvalue>
17486 <entry role=
"func_table_entry"><para role=
"func_signature">
17487 <literal>false
</literal>
17488 <returnvalue>boolean
</returnvalue>
17491 JSON constant
<literal>false
</literal>
17494 <literal>jsonb_path_query('[{
"name":
"John",
"parent": false}, {
"name":
"Chris",
"parent": true}]', '$[*] ? (@.parent == false)')
</literal>
17495 <returnvalue>{
"name":
"John",
"parent": false}
</returnvalue>
17500 <entry role=
"func_table_entry"><para role=
"func_signature">
17501 <literal>null
</literal>
17502 <returnvalue><replaceable>value
</replaceable></returnvalue>
17505 JSON constant
<literal>null
</literal> (note that, unlike in SQL,
17506 comparison to
<literal>null
</literal> works normally)
17509 <literal>jsonb_path_query('[{
"name":
"Mary",
"job": null}, {
"name":
"Michael",
"job":
"driver"}]', '$[*] ? (@.job == null) .name')
</literal>
17510 <returnvalue>"Mary"</returnvalue>
17515 <entry role=
"func_table_entry"><para role=
"func_signature">
17516 <replaceable>boolean
</replaceable> <literal>&&</literal> <replaceable>boolean
</replaceable>
17517 <returnvalue>boolean
</returnvalue>
17523 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (@
> 1 && @
< 5)')
</literal>
17524 <returnvalue>3</returnvalue>
17529 <entry role=
"func_table_entry"><para role=
"func_signature">
17530 <replaceable>boolean
</replaceable> <literal>||
</literal> <replaceable>boolean
</replaceable>
17531 <returnvalue>boolean
</returnvalue>
17537 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (@
< 1 || @
> 5)')
</literal>
17538 <returnvalue>7</returnvalue>
17543 <entry role=
"func_table_entry"><para role=
"func_signature">
17544 <literal>!
</literal> <replaceable>boolean
</replaceable>
17545 <returnvalue>boolean
</returnvalue>
17551 <literal>jsonb_path_query('[
1,
3,
7]', '$[*] ? (!(@
< 5))')
</literal>
17552 <returnvalue>7</returnvalue>
17557 <entry role=
"func_table_entry"><para role=
"func_signature">
17558 <replaceable>boolean
</replaceable> <literal>is unknown
</literal>
17559 <returnvalue>boolean
</returnvalue>
17562 Tests whether a Boolean condition is
<literal>unknown
</literal>.
17565 <literal>jsonb_path_query('[-
1,
2,
7,
"foo"]', '$[*] ? ((@
> 0) is unknown)')
</literal>
17566 <returnvalue>"foo"</returnvalue>
17571 <entry role=
"func_table_entry"><para role=
"func_signature">
17572 <replaceable>string
</replaceable> <literal>like_regex
</literal> <replaceable>string
</replaceable> <optional> <literal>flag
</literal> <replaceable>string
</replaceable> </optional>
17573 <returnvalue>boolean
</returnvalue>
17576 Tests whether the first operand matches the regular expression
17577 given by the second operand, optionally with modifications
17578 described by a string of
<literal>flag
</literal> characters (see
17579 <xref linkend=
"jsonpath-regular-expressions"/>).
17582 <literal>jsonb_path_query_array('[
"abc",
"abd",
"aBdC",
"abdacb",
"babc"]', '$[*] ? (@ like_regex
"^ab.*c")')
</literal>
17583 <returnvalue>[
"abc",
"abdacb"]
</returnvalue>
17586 <literal>jsonb_path_query_array('[
"abc",
"abd",
"aBdC",
"abdacb",
"babc"]', '$[*] ? (@ like_regex
"^ab.*c" flag
"i")')
</literal>
17587 <returnvalue>[
"abc",
"aBdC",
"abdacb"]
</returnvalue>
17592 <entry role=
"func_table_entry"><para role=
"func_signature">
17593 <replaceable>string
</replaceable> <literal>starts with
</literal> <replaceable>string
</replaceable>
17594 <returnvalue>boolean
</returnvalue>
17597 Tests whether the second operand is an initial substring of the first
17601 <literal>jsonb_path_query('[
"John Smith",
"Mary Stone",
"Bob Johnson"]', '$[*] ? (@ starts with
"John")')
</literal>
17602 <returnvalue>"John Smith"</returnvalue>
17607 <entry role=
"func_table_entry"><para role=
"func_signature">
17608 <literal>exists
</literal> <literal>(
</literal> <replaceable>path_expression
</replaceable> <literal>)
</literal>
17609 <returnvalue>boolean
</returnvalue>
17612 Tests whether a path expression matches at least one SQL/JSON item.
17613 Returns
<literal>unknown
</literal> if the path expression would result
17614 in an error; the second example uses this to avoid a no-such-key error
17618 <literal>jsonb_path_query('{
"x": [
1,
2],
"y": [
2,
4]}', 'strict $.* ? (exists (@ ? (@[*]
> 2)))')
</literal>
17619 <returnvalue>[
2,
4]
</returnvalue>
17622 <literal>jsonb_path_query_array('{
"value":
41}', 'strict $ ? (exists (@.name)) .name')
</literal>
17623 <returnvalue>[]
</returnvalue>
17632 <sect3 id=
"jsonpath-regular-expressions">
17633 <title>SQL/JSON Regular Expressions
</title>
17635 <indexterm zone=
"jsonpath-regular-expressions">
17636 <primary><literal>LIKE_REGEX
</literal></primary>
17637 <secondary>in SQL/JSON
</secondary>
17641 SQL/JSON path expressions allow matching text to a regular expression
17642 with the
<literal>like_regex
</literal> filter. For example, the
17643 following SQL/JSON path query would case-insensitively match all
17644 strings in an array that start with an English vowel:
17646 $[*] ? (@ like_regex
"^[aeiou]" flag
"i")
17651 The optional
<literal>flag
</literal> string may include one or more of
17653 <literal>i
</literal> for case-insensitive match,
17654 <literal>m
</literal> to allow
<literal>^
</literal>
17655 and
<literal>$
</literal> to match at newlines,
17656 <literal>s
</literal> to allow
<literal>.
</literal> to match a newline,
17657 and
<literal>q
</literal> to quote the whole pattern (reducing the
17658 behavior to a simple substring match).
17662 The SQL/JSON standard borrows its definition for regular expressions
17663 from the
<literal>LIKE_REGEX
</literal> operator, which in turn uses the
17664 XQuery standard. PostgreSQL does not currently support the
17665 <literal>LIKE_REGEX
</literal> operator. Therefore,
17666 the
<literal>like_regex
</literal> filter is implemented using the
17667 POSIX regular expression engine described in
17668 <xref linkend=
"functions-posix-regexp"/>. This leads to various minor
17669 discrepancies from standard SQL/JSON behavior, which are cataloged in
17670 <xref linkend=
"posix-vs-xquery"/>.
17671 Note, however, that the flag-letter incompatibilities described there
17672 do not apply to SQL/JSON, as it translates the XQuery flag letters to
17673 match what the POSIX engine expects.
17677 Keep in mind that the pattern argument of
<literal>like_regex
</literal>
17678 is a JSON path string literal, written according to the rules given in
17679 <xref linkend=
"datatype-jsonpath"/>. This means in particular that any
17680 backslashes you want to use in the regular expression must be doubled.
17681 For example, to match string values of the root document that contain
17684 $.* ? (@ like_regex
"^\\d+$")
17691 <sect1 id=
"functions-sequence">
17692 <title>Sequence Manipulation Functions
</title>
17695 <primary>sequence
</primary>
17699 This section describes functions for operating on
<firstterm>sequence
17700 objects
</firstterm>, also called sequence generators or just sequences.
17701 Sequence objects are special single-row tables created with
<xref
17702 linkend=
"sql-createsequence"/>.
17703 Sequence objects are commonly used to generate unique identifiers
17704 for rows of a table. The sequence functions, listed in
<xref
17705 linkend=
"functions-sequence-table"/>, provide simple, multiuser-safe
17706 methods for obtaining successive sequence values from sequence
17710 <table id=
"functions-sequence-table">
17711 <title>Sequence Functions
</title>
17715 <entry role=
"func_table_entry"><para role=
"func_signature">
17726 <entry role=
"func_table_entry"><para role=
"func_signature">
17728 <primary>nextval
</primary>
17730 <function>nextval
</function> (
<type>regclass
</type> )
17731 <returnvalue>bigint
</returnvalue>
17734 Advances the sequence object to its next value and returns that value.
17735 This is done atomically: even if multiple sessions
17736 execute
<function>nextval
</function> concurrently, each will safely
17737 receive a distinct sequence value.
17738 If the sequence object has been created with default parameters,
17739 successive
<function>nextval
</function> calls will return successive
17740 values beginning with
1. Other behaviors can be obtained by using
17741 appropriate parameters in the
<xref linkend=
"sql-createsequence"/>
17745 This function requires
<literal>USAGE
</literal>
17746 or
<literal>UPDATE
</literal> privilege on the sequence.
17751 <entry role=
"func_table_entry"><para role=
"func_signature">
17753 <primary>setval
</primary>
17755 <function>setval
</function> (
<type>regclass
</type>,
<type>bigint
</type> <optional>,
<type>boolean
</type> </optional> )
17756 <returnvalue>bigint
</returnvalue>
17759 Sets the sequence object's current value, and optionally
17760 its
<literal>is_called
</literal> flag. The two-parameter
17761 form sets the sequence's
<literal>last_value
</literal> field to the
17762 specified value and sets its
<literal>is_called
</literal> field to
17763 <literal>true
</literal>, meaning that the next
17764 <function>nextval
</function> will advance the sequence before
17765 returning a value. The value that will be reported
17766 by
<function>currval
</function> is also set to the specified value.
17767 In the three-parameter form,
<literal>is_called
</literal> can be set
17768 to either
<literal>true
</literal>
17769 or
<literal>false
</literal>.
<literal>true
</literal> has the same
17770 effect as the two-parameter form. If it is set
17771 to
<literal>false
</literal>, the next
<function>nextval
</function>
17772 will return exactly the specified value, and sequence advancement
17773 commences with the following
<function>nextval
</function>.
17774 Furthermore, the value reported by
<function>currval
</function> is not
17775 changed in this case. For example,
17777 SELECT setval('myseq',
42);
<lineannotation>Next
<function>nextval
</function> will return
43</lineannotation>
17778 SELECT setval('myseq',
42, true);
<lineannotation>Same as above
</lineannotation>
17779 SELECT setval('myseq',
42, false);
<lineannotation>Next
<function>nextval
</function> will return
42</lineannotation>
17781 The result returned by
<function>setval
</function> is just the value of its
17785 This function requires
<literal>UPDATE
</literal> privilege on the
17791 <entry role=
"func_table_entry"><para role=
"func_signature">
17793 <primary>currval
</primary>
17795 <function>currval
</function> (
<type>regclass
</type> )
17796 <returnvalue>bigint
</returnvalue>
17799 Returns the value most recently obtained
17800 by
<function>nextval
</function> for this sequence in the current
17801 session. (An error is reported if
<function>nextval
</function> has
17802 never been called for this sequence in this session.) Because this is
17803 returning a session-local value, it gives a predictable answer whether
17804 or not other sessions have executed
<function>nextval
</function> since
17805 the current session did.
17808 This function requires
<literal>USAGE
</literal>
17809 or
<literal>SELECT
</literal> privilege on the sequence.
17814 <entry role=
"func_table_entry"><para role=
"func_signature">
17816 <primary>lastval
</primary>
17818 <function>lastval
</function> ()
17819 <returnvalue>bigint
</returnvalue>
17822 Returns the value most recently returned by
17823 <function>nextval
</function> in the current session. This function is
17824 identical to
<function>currval
</function>, except that instead
17825 of taking the sequence name as an argument it refers to whichever
17826 sequence
<function>nextval
</function> was most recently applied to
17827 in the current session. It is an error to call
17828 <function>lastval
</function> if
<function>nextval
</function>
17829 has not yet been called in the current session.
17832 This function requires
<literal>USAGE
</literal>
17833 or
<literal>SELECT
</literal> privilege on the last used sequence.
17842 To avoid blocking concurrent transactions that obtain numbers from
17843 the same sequence, the value obtained by
<function>nextval
</function>
17844 is not reclaimed for re-use if the calling transaction later aborts.
17845 This means that transaction aborts or database crashes can result in
17846 gaps in the sequence of assigned values. That can happen without a
17847 transaction abort, too. For example an
<command>INSERT
</command> with
17848 an
<literal>ON CONFLICT
</literal> clause will compute the to-be-inserted
17849 tuple, including doing any required
<function>nextval
</function>
17850 calls, before detecting any conflict that would cause it to follow
17851 the
<literal>ON CONFLICT
</literal> rule instead.
17852 Thus,
<productname>PostgreSQL
</productname> sequence
17853 objects
<emphasis>cannot be used to obtain
<quote>gapless
</quote>
17854 sequences
</emphasis>.
17858 Likewise, sequence state changes made by
<function>setval
</function>
17859 are immediately visible to other transactions, and are not undone if
17860 the calling transaction rolls back.
17864 If the database cluster crashes before committing a transaction
17865 containing a
<function>nextval
</function>
17866 or
<function>setval
</function> call, the sequence state change might
17867 not have made its way to persistent storage, so that it is uncertain
17868 whether the sequence will have its original or updated state after the
17869 cluster restarts. This is harmless for usage of the sequence within
17870 the database, since other effects of uncommitted transactions will not
17871 be visible either. However, if you wish to use a sequence value for
17872 persistent outside-the-database purposes, make sure that the
17873 <function>nextval
</function> call has been committed before doing so.
17878 The sequence to be operated on by a sequence function is specified by
17879 a
<type>regclass
</type> argument, which is simply the OID of the sequence in the
17880 <structname>pg_class
</structname> system catalog. You do not have to look up the
17881 OID by hand, however, since the
<type>regclass
</type> data type's input
17882 converter will do the work for you. See
<xref linkend=
"datatype-oid"/>
17888 <sect1 id=
"functions-conditional">
17889 <title>Conditional Expressions
</title>
17892 <primary>CASE
</primary>
17896 <primary>conditional expression
</primary>
17900 This section describes the
<acronym>SQL
</acronym>-compliant conditional expressions
17901 available in
<productname>PostgreSQL
</productname>.
17906 If your needs go beyond the capabilities of these conditional
17907 expressions, you might want to consider writing a server-side function
17908 in a more expressive programming language.
17914 Although
<token>COALESCE
</token>,
<token>GREATEST
</token>, and
17915 <token>LEAST
</token> are syntactically similar to functions, they are
17916 not ordinary functions, and thus cannot be used with explicit
17917 <token>VARIADIC
</token> array arguments.
17921 <sect2 id=
"functions-case">
17922 <title><literal>CASE
</literal></title>
17925 The
<acronym>SQL
</acronym> <token>CASE
</token> expression is a
17926 generic conditional expression, similar to if/else statements in
17927 other programming languages:
17930 CASE WHEN
<replaceable>condition
</replaceable> THEN
<replaceable>result
</replaceable>
17931 <optional>WHEN ...
</optional>
17932 <optional>ELSE
<replaceable>result
</replaceable></optional>
17936 <token>CASE
</token> clauses can be used wherever
17937 an expression is valid. Each
<replaceable>condition
</replaceable> is an
17938 expression that returns a
<type>boolean
</type> result. If the condition's
17939 result is true, the value of the
<token>CASE
</token> expression is the
17940 <replaceable>result
</replaceable> that follows the condition, and the
17941 remainder of the
<token>CASE
</token> expression is not processed. If the
17942 condition's result is not true, any subsequent
<token>WHEN
</token> clauses
17943 are examined in the same manner. If no
<token>WHEN
</token>
17944 <replaceable>condition
</replaceable> yields true, the value of the
17945 <token>CASE
</token> expression is the
<replaceable>result
</replaceable> of the
17946 <token>ELSE
</token> clause. If the
<token>ELSE
</token> clause is
17947 omitted and no condition is true, the result is null.
17953 SELECT * FROM test;
17963 CASE WHEN a=
1 THEN 'one'
17964 WHEN a=
2 THEN 'two'
17978 The data types of all the
<replaceable>result
</replaceable>
17979 expressions must be convertible to a single output type.
17980 See
<xref linkend=
"typeconv-union-case"/> for more details.
17984 There is a
<quote>simple
</quote> form of
<token>CASE
</token> expression
17985 that is a variant of the general form above:
17988 CASE
<replaceable>expression
</replaceable>
17989 WHEN
<replaceable>value
</replaceable> THEN
<replaceable>result
</replaceable>
17990 <optional>WHEN ...
</optional>
17991 <optional>ELSE
<replaceable>result
</replaceable></optional>
17996 <replaceable>expression
</replaceable> is computed, then compared to
17997 each of the
<replaceable>value
</replaceable> expressions in the
17998 <token>WHEN
</token> clauses until one is found that is equal to it. If
17999 no match is found, the
<replaceable>result
</replaceable> of the
18000 <token>ELSE
</token> clause (or a null value) is returned. This is similar
18001 to the
<function>switch
</function> statement in C.
18005 The example above can be written using the simple
18006 <token>CASE
</token> syntax:
18009 CASE a WHEN
1 THEN 'one'
18024 A
<token>CASE
</token> expression does not evaluate any subexpressions
18025 that are not needed to determine the result. For example, this is a
18026 possible way of avoiding a division-by-zero failure:
18028 SELECT ... WHERE CASE WHEN x
<> 0 THEN y/x
> 1.5 ELSE false END;
18034 As described in
<xref linkend=
"syntax-express-eval"/>, there are various
18035 situations in which subexpressions of an expression are evaluated at
18036 different times, so that the principle that
<quote><token>CASE
</token>
18037 evaluates only necessary subexpressions
</quote> is not ironclad. For
18038 example a constant
<literal>1/
0</literal> subexpression will usually result in
18039 a division-by-zero failure at planning time, even if it's within
18040 a
<token>CASE
</token> arm that would never be entered at run time.
18045 <sect2 id=
"functions-coalesce-nvl-ifnull">
18046 <title><literal>COALESCE
</literal></title>
18049 <primary>COALESCE
</primary>
18053 <primary>NVL
</primary>
18057 <primary>IFNULL
</primary>
18061 <function>COALESCE
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
18065 The
<function>COALESCE
</function> function returns the first of its
18066 arguments that is not null. Null is returned only if all arguments
18067 are null. It is often used to substitute a default value for
18068 null values when data is retrieved for display, for example:
18070 SELECT COALESCE(description, short_description, '(none)') ...
18072 This returns
<varname>description
</varname> if it is not null, otherwise
18073 <varname>short_description
</varname> if it is not null, otherwise
<literal>(none)
</literal>.
18077 The arguments must all be convertible to a common data type, which
18078 will be the type of the result (see
18079 <xref linkend=
"typeconv-union-case"/> for details).
18083 Like a
<token>CASE
</token> expression,
<function>COALESCE
</function> only
18084 evaluates the arguments that are needed to determine the result;
18085 that is, arguments to the right of the first non-null argument are
18086 not evaluated. This SQL-standard function provides capabilities similar
18087 to
<function>NVL
</function> and
<function>IFNULL
</function>, which are used in some other
18092 <sect2 id=
"functions-nullif">
18093 <title><literal>NULLIF
</literal></title>
18096 <primary>NULLIF
</primary>
18100 <function>NULLIF
</function>(
<replaceable>value1
</replaceable>,
<replaceable>value2
</replaceable>)
18104 The
<function>NULLIF
</function> function returns a null value if
18105 <replaceable>value1
</replaceable> equals
<replaceable>value2
</replaceable>;
18106 otherwise it returns
<replaceable>value1
</replaceable>.
18107 This can be used to perform the inverse operation of the
18108 <function>COALESCE
</function> example given above:
18110 SELECT NULLIF(value, '(none)') ...
18112 In this example, if
<literal>value
</literal> is
<literal>(none)
</literal>,
18113 null is returned, otherwise the value of
<literal>value
</literal>
18118 The two arguments must be of comparable types.
18119 To be specific, they are compared exactly as if you had
18120 written
<literal><replaceable>value1
</replaceable>
18121 =
<replaceable>value2
</replaceable></literal>, so there must be a
18122 suitable
<literal>=
</literal> operator available.
18126 The result has the same type as the first argument
— but there is
18127 a subtlety. What is actually returned is the first argument of the
18128 implied
<literal>=
</literal> operator, and in some cases that will have
18129 been promoted to match the second argument's type. For
18130 example,
<literal>NULLIF(
1,
2.2)
</literal> yields
<type>numeric
</type>,
18131 because there is no
<type>integer
</type> <literal>=
</literal>
18132 <type>numeric
</type> operator,
18133 only
<type>numeric
</type> <literal>=
</literal> <type>numeric
</type>.
18138 <sect2 id=
"functions-greatest-least">
18139 <title><literal>GREATEST
</literal> and
<literal>LEAST
</literal></title>
18142 <primary>GREATEST
</primary>
18145 <primary>LEAST
</primary>
18149 <function>GREATEST
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
18152 <function>LEAST
</function>(
<replaceable>value
</replaceable> <optional>, ...
</optional>)
18156 The
<function>GREATEST
</function> and
<function>LEAST
</function> functions select the
18157 largest or smallest value from a list of any number of expressions.
18158 The expressions must all be convertible to a common data type, which
18159 will be the type of the result
18160 (see
<xref linkend=
"typeconv-union-case"/> for details). NULL values
18161 in the list are ignored. The result will be NULL only if all the
18162 expressions evaluate to NULL.
18166 Note that
<function>GREATEST
</function> and
<function>LEAST
</function> are not in
18167 the SQL standard, but are a common extension. Some other databases
18168 make them return NULL if any argument is NULL, rather than only when
18174 <sect1 id=
"functions-array">
18175 <title>Array Functions and Operators
</title>
18178 <xref linkend=
"array-operators-table"/> shows the specialized operators
18179 available for array types.
18180 In addition to those, the usual comparison operators shown in
<xref
18181 linkend=
"functions-comparison-op-table"/> are available for
18182 arrays. The comparison operators compare the array contents
18183 element-by-element, using the default B-tree comparison function for
18184 the element data type, and sort based on the first difference.
18185 In multidimensional arrays the elements are visited in row-major order
18186 (last subscript varies most rapidly).
18187 If the contents of two arrays are equal but the dimensionality is
18188 different, the first difference in the dimensionality information
18189 determines the sort order.
18192 <table id=
"array-operators-table">
18193 <title>Array Operators
</title>
18197 <entry role=
"func_table_entry"><para role=
"func_signature">
18211 <entry role=
"func_table_entry"><para role=
"func_signature">
18212 <type>anyarray
</type> <literal>@
></literal> <type>anyarray
</type>
18213 <returnvalue>boolean
</returnvalue>
18216 Does the first array contain the second, that is, does each element
18217 appearing in the second array equal some element of the first array?
18218 (Duplicates are not treated specially,
18219 thus
<literal>ARRAY[
1]
</literal> and
<literal>ARRAY[
1,
1]
</literal> are
18220 each considered to contain the other.)
18223 <literal>ARRAY[
1,
4,
3] @
> ARRAY[
3,
1,
3]
</literal>
18224 <returnvalue>t
</returnvalue>
18229 <entry role=
"func_table_entry"><para role=
"func_signature">
18230 <type>anyarray
</type> <literal><@
</literal> <type>anyarray
</type>
18231 <returnvalue>boolean
</returnvalue>
18234 Is the first array contained by the second?
18237 <literal>ARRAY[
2,
2,
7]
<@ ARRAY[
1,
7,
4,
2,
6]
</literal>
18238 <returnvalue>t
</returnvalue>
18243 <entry role=
"func_table_entry"><para role=
"func_signature">
18244 <type>anyarray
</type> <literal>&&</literal> <type>anyarray
</type>
18245 <returnvalue>boolean
</returnvalue>
18248 Do the arrays overlap, that is, have any elements in common?
18251 <literal>ARRAY[
1,
4,
3]
&& ARRAY[
2,
1]
</literal>
18252 <returnvalue>t
</returnvalue>
18257 <entry role=
"func_table_entry"><para role=
"func_signature">
18258 <type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
18259 <returnvalue>anycompatiblearray
</returnvalue>
18262 Concatenates the two arrays. Concatenating a null or empty array is a
18263 no-op; otherwise the arrays must have the same number of dimensions
18264 (as illustrated by the first example) or differ in number of
18265 dimensions by one (as illustrated by the second).
18266 If the arrays are not of identical element types, they will be coerced
18267 to a common type (see
<xref linkend=
"typeconv-union-case"/>).
18270 <literal>ARRAY[
1,
2,
3] || ARRAY[
4,
5,
6,
7]
</literal>
18271 <returnvalue>{
1,
2,
3,
4,
5,
6,
7}
</returnvalue>
18274 <literal>ARRAY[
1,
2,
3] || ARRAY[[
4,
5,
6],[
7,
8,
9.9]]
</literal>
18275 <returnvalue>{{
1,
2,
3},{
4,
5,
6},{
7,
8,
9.9}}
</returnvalue>
18280 <entry role=
"func_table_entry"><para role=
"func_signature">
18281 <type>anycompatible
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
18282 <returnvalue>anycompatiblearray
</returnvalue>
18285 Concatenates an element onto the front of an array (which must be
18286 empty or one-dimensional).
18289 <literal>3 || ARRAY[
4,
5,
6]
</literal>
18290 <returnvalue>{
3,
4,
5,
6}
</returnvalue>
18295 <entry role=
"func_table_entry"><para role=
"func_signature">
18296 <type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatible
</type>
18297 <returnvalue>anycompatiblearray
</returnvalue>
18300 Concatenates an element onto the end of an array (which must be
18301 empty or one-dimensional).
18304 <literal>ARRAY[
4,
5,
6] ||
7</literal>
18305 <returnvalue>{
4,
5,
6,
7}
</returnvalue>
18313 See
<xref linkend=
"arrays"/> for more details about array operator
18314 behavior. See
<xref linkend=
"indexes-types"/> for more details about
18315 which operators support indexed operations.
18319 <xref linkend=
"array-functions-table"/> shows the functions
18320 available for use with array types. See
<xref linkend=
"arrays"/>
18321 for more information and examples of the use of these functions.
18324 <table id=
"array-functions-table">
18325 <title>Array Functions
</title>
18329 <entry role=
"func_table_entry"><para role=
"func_signature">
18343 <entry role=
"func_table_entry"><para role=
"func_signature">
18345 <primary>array_append
</primary>
18347 <function>array_append
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
18348 <returnvalue>anycompatiblearray
</returnvalue>
18351 Appends an element to the end of an array (same as
18352 the
<type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatible
</type>
18356 <literal>array_append(ARRAY[
1,
2],
3)
</literal>
18357 <returnvalue>{
1,
2,
3}
</returnvalue>
18362 <entry role=
"func_table_entry"><para role=
"func_signature">
18364 <primary>array_cat
</primary>
18366 <function>array_cat
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatiblearray
</type> )
18367 <returnvalue>anycompatiblearray
</returnvalue>
18370 Concatenates two arrays (same as
18371 the
<type>anycompatiblearray
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
18375 <literal>array_cat(ARRAY[
1,
2,
3], ARRAY[
4,
5])
</literal>
18376 <returnvalue>{
1,
2,
3,
4,
5}
</returnvalue>
18381 <entry role=
"func_table_entry"><para role=
"func_signature">
18383 <primary>array_dims
</primary>
18385 <function>array_dims
</function> (
<type>anyarray
</type> )
18386 <returnvalue>text
</returnvalue>
18389 Returns a text representation of the array's dimensions.
18392 <literal>array_dims(ARRAY[[
1,
2,
3], [
4,
5,
6]])
</literal>
18393 <returnvalue>[
1:
2][
1:
3]
</returnvalue>
18398 <entry role=
"func_table_entry"><para role=
"func_signature">
18400 <primary>array_fill
</primary>
18402 <function>array_fill
</function> (
<type>anyelement
</type>,
<type>integer[]
</type>
18403 <optional>,
<type>integer[]
</type> </optional> )
18404 <returnvalue>anyarray
</returnvalue>
18407 Returns an array filled with copies of the given value, having
18408 dimensions of the lengths specified by the second argument.
18409 The optional third argument supplies lower-bound values for each
18410 dimension (which default to all
<literal>1</literal>).
18413 <literal>array_fill(
11, ARRAY[
2,
3])
</literal>
18414 <returnvalue>{{
11,
11,
11},{
11,
11,
11}}
</returnvalue>
18417 <literal>array_fill(
7, ARRAY[
3], ARRAY[
2])
</literal>
18418 <returnvalue>[
2:
4]={
7,
7,
7}
</returnvalue>
18423 <entry role=
"func_table_entry"><para role=
"func_signature">
18425 <primary>array_length
</primary>
18427 <function>array_length
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
18428 <returnvalue>integer
</returnvalue>
18431 Returns the length of the requested array dimension.
18432 (Produces NULL instead of
0 for empty or missing array dimensions.)
18435 <literal>array_length(array[
1,
2,
3],
1)
</literal>
18436 <returnvalue>3</returnvalue>
18439 <literal>array_length(array[]::int[],
1)
</literal>
18440 <returnvalue>NULL
</returnvalue>
18443 <literal>array_length(array['text'],
2)
</literal>
18444 <returnvalue>NULL
</returnvalue>
18449 <entry role=
"func_table_entry"><para role=
"func_signature">
18451 <primary>array_lower
</primary>
18453 <function>array_lower
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
18454 <returnvalue>integer
</returnvalue>
18457 Returns the lower bound of the requested array dimension.
18460 <literal>array_lower('[
0:
2]={
1,
2,
3}'::integer[],
1)
</literal>
18461 <returnvalue>0</returnvalue>
18466 <entry role=
"func_table_entry"><para role=
"func_signature">
18468 <primary>array_ndims
</primary>
18470 <function>array_ndims
</function> (
<type>anyarray
</type> )
18471 <returnvalue>integer
</returnvalue>
18474 Returns the number of dimensions of the array.
18477 <literal>array_ndims(ARRAY[[
1,
2,
3], [
4,
5,
6]])
</literal>
18478 <returnvalue>2</returnvalue>
18483 <entry role=
"func_table_entry"><para role=
"func_signature">
18485 <primary>array_position
</primary>
18487 <function>array_position
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> <optional>,
<type>integer
</type> </optional> )
18488 <returnvalue>integer
</returnvalue>
18491 Returns the subscript of the first occurrence of the second argument
18492 in the array, or
<literal>NULL
</literal> if it's not present.
18493 If the third argument is given, the search begins at that subscript.
18494 The array must be one-dimensional.
18495 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
18496 semantics, so it is possible to search for
<literal>NULL
</literal>.
18499 <literal>array_position(ARRAY['sun', 'mon', 'tue', 'wed', 'thu', 'fri', 'sat'], 'mon')
</literal>
18500 <returnvalue>2</returnvalue>
18505 <entry role=
"func_table_entry"><para role=
"func_signature">
18507 <primary>array_positions
</primary>
18509 <function>array_positions
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
18510 <returnvalue>integer[]
</returnvalue>
18513 Returns an array of the subscripts of all occurrences of the second
18514 argument in the array given as first argument.
18515 The array must be one-dimensional.
18516 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
18517 semantics, so it is possible to search for
<literal>NULL
</literal>.
18518 <literal>NULL
</literal> is returned only if the array
18519 is
<literal>NULL
</literal>; if the value is not found in the array, an
18520 empty array is returned.
18523 <literal>array_positions(ARRAY['A','A','B','A'], 'A')
</literal>
18524 <returnvalue>{
1,
2,
4}
</returnvalue>
18529 <entry role=
"func_table_entry"><para role=
"func_signature">
18531 <primary>array_prepend
</primary>
18533 <function>array_prepend
</function> (
<type>anycompatible
</type>,
<type>anycompatiblearray
</type> )
18534 <returnvalue>anycompatiblearray
</returnvalue>
18537 Prepends an element to the beginning of an array (same as
18538 the
<type>anycompatible
</type> <literal>||
</literal> <type>anycompatiblearray
</type>
18542 <literal>array_prepend(
1, ARRAY[
2,
3])
</literal>
18543 <returnvalue>{
1,
2,
3}
</returnvalue>
18548 <entry role=
"func_table_entry"><para role=
"func_signature">
18550 <primary>array_remove
</primary>
18552 <function>array_remove
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type> )
18553 <returnvalue>anycompatiblearray
</returnvalue>
18556 Removes all elements equal to the given value from the array.
18557 The array must be one-dimensional.
18558 Comparisons are done using
<literal>IS NOT DISTINCT FROM
</literal>
18559 semantics, so it is possible to remove
<literal>NULL
</literal>s.
18562 <literal>array_remove(ARRAY[
1,
2,
3,
2],
2)
</literal>
18563 <returnvalue>{
1,
3}
</returnvalue>
18568 <entry role=
"func_table_entry"><para role=
"func_signature">
18570 <primary>array_replace
</primary>
18572 <function>array_replace
</function> (
<type>anycompatiblearray
</type>,
<type>anycompatible
</type>,
<type>anycompatible
</type> )
18573 <returnvalue>anycompatiblearray
</returnvalue>
18576 Replaces each array element equal to the second argument with the
18580 <literal>array_replace(ARRAY[
1,
2,
5,
4],
5,
3)
</literal>
18581 <returnvalue>{
1,
2,
3,
4}
</returnvalue>
18586 <entry role=
"func_table_entry"><para role=
"func_signature">
18587 <indexterm id=
"function-array-to-string">
18588 <primary>array_to_string
</primary>
18590 <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> )
18591 <returnvalue>text
</returnvalue>
18594 Converts each array element to its text representation, and
18595 concatenates those separated by
18596 the
<parameter>delimiter
</parameter> string.
18597 If
<parameter>null_string
</parameter> is given and is
18598 not
<literal>NULL
</literal>, then
<literal>NULL
</literal> array
18599 entries are represented by that string; otherwise, they are omitted.
18600 See also
<link linkend=
"function-string-to-array"><function>string_to_array
</function></link>.
18603 <literal>array_to_string(ARRAY[
1,
2,
3, NULL,
5], ',', '*')
</literal>
18604 <returnvalue>1,
2,
3,*,
5</returnvalue>
18609 <entry role=
"func_table_entry"><para role=
"func_signature">
18611 <primary>array_upper
</primary>
18613 <function>array_upper
</function> (
<type>anyarray
</type>,
<type>integer
</type> )
18614 <returnvalue>integer
</returnvalue>
18617 Returns the upper bound of the requested array dimension.
18620 <literal>array_upper(ARRAY[
1,
8,
3,
7],
1)
</literal>
18621 <returnvalue>4</returnvalue>
18626 <entry role=
"func_table_entry"><para role=
"func_signature">
18628 <primary>cardinality
</primary>
18630 <function>cardinality
</function> (
<type>anyarray
</type> )
18631 <returnvalue>integer
</returnvalue>
18634 Returns the total number of elements in the array, or
0 if the array
18638 <literal>cardinality(ARRAY[[
1,
2],[
3,
4]])
</literal>
18639 <returnvalue>4</returnvalue>
18644 <entry role=
"func_table_entry"><para role=
"func_signature">
18646 <primary>trim_array
</primary>
18648 <function>trim_array
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>n
</parameter> <type>integer
</type> )
18649 <returnvalue>anyarray
</returnvalue>
18652 Trims an array by removing the last
<parameter>n
</parameter> elements.
18653 If the array is multidimensional, only the first dimension is trimmed.
18656 <literal>trim_array(ARRAY[
1,
2,
3,
4,
5,
6],
2)
</literal>
18657 <returnvalue>{
1,
2,
3,
4}
</returnvalue>
18662 <entry role=
"func_table_entry"><para role=
"func_signature">
18664 <primary>unnest
</primary>
18666 <function>unnest
</function> (
<type>anyarray
</type> )
18667 <returnvalue>setof anyelement
</returnvalue>
18670 Expands an array into a set of rows.
18671 The array's elements are read out in storage order.
18674 <literal>unnest(ARRAY[
1,
2])
</literal>
18675 <returnvalue></returnvalue>
18682 <literal>unnest(ARRAY[['foo','bar'],['baz','quux']])
</literal>
18683 <returnvalue></returnvalue>
18694 <entry role=
"func_table_entry"><para role=
"func_signature">
18695 <function>unnest
</function> (
<type>anyarray
</type>,
<type>anyarray
</type> <optional>, ...
</optional> )
18696 <returnvalue>setof anyelement, anyelement [, ... ]
</returnvalue>
18699 Expands multiple arrays (possibly of different data types) into a set of
18700 rows. If the arrays are not all the same length then the shorter ones
18701 are padded with
<literal>NULL
</literal>s. This form is only allowed
18702 in a query's FROM clause; see
<xref linkend=
"queries-tablefunctions"/>.
18705 <literal>select * from unnest(ARRAY[
1,
2], ARRAY['foo','bar','baz']) as x(a,b)
</literal>
18706 <returnvalue></returnvalue>
18721 See also
<xref linkend=
"functions-aggregate"/> about the aggregate
18722 function
<function>array_agg
</function> for use with arrays.
18726 <sect1 id=
"functions-range">
18727 <title>Range/Multirange Functions and Operators
</title>
18730 See
<xref linkend=
"rangetypes"/> for an overview of range types.
18734 <xref linkend=
"range-operators-table"/> shows the specialized operators
18735 available for range types.
18736 <xref linkend=
"multirange-operators-table"/> shows the specialized operators
18737 available for multirange types.
18738 In addition to those, the usual comparison operators shown in
18739 <xref linkend=
"functions-comparison-op-table"/> are available for range
18740 and multirange types. The comparison operators order first by the range lower
18741 bounds, and only if those are equal do they compare the upper bounds. The
18742 multirange operators compare each range until one is unequal. This
18743 does not usually result in a useful overall ordering, but the operators are
18744 provided to allow unique indexes to be constructed on ranges.
18747 <table id=
"range-operators-table">
18748 <title>Range Operators
</title>
18752 <entry role=
"func_table_entry"><para role=
"func_signature">
18766 <entry role=
"func_table_entry"><para role=
"func_signature">
18767 <type>anyrange
</type> <literal>@
></literal> <type>anyrange
</type>
18768 <returnvalue>boolean
</returnvalue>
18771 Does the first range contain the second?
18774 <literal>int4range(
2,
4) @
> int4range(
2,
3)
</literal>
18775 <returnvalue>t
</returnvalue>
18780 <entry role=
"func_table_entry"><para role=
"func_signature">
18781 <type>anyrange
</type> <literal>@
></literal> <type>anyelement
</type>
18782 <returnvalue>boolean
</returnvalue>
18785 Does the range contain the element?
18788 <literal>'[
2011-
01-
01,
2011-
03-
01)'::tsrange @
> '
2011-
01-
10'::timestamp
</literal>
18789 <returnvalue>t
</returnvalue>
18794 <entry role=
"func_table_entry"><para role=
"func_signature">
18795 <type>anyrange
</type> <literal><@
</literal> <type>anyrange
</type>
18796 <returnvalue>boolean
</returnvalue>
18799 Is the first range contained by the second?
18802 <literal>int4range(
2,
4)
<@ int4range(
1,
7)
</literal>
18803 <returnvalue>t
</returnvalue>
18808 <entry role=
"func_table_entry"><para role=
"func_signature">
18809 <type>anyelement
</type> <literal><@
</literal> <type>anyrange
</type>
18810 <returnvalue>boolean
</returnvalue>
18813 Is the element contained in the range?
18816 <literal>42 <@ int4range(
1,
7)
</literal>
18817 <returnvalue>f
</returnvalue>
18822 <entry role=
"func_table_entry"><para role=
"func_signature">
18823 <type>anyrange
</type> <literal>&&</literal> <type>anyrange
</type>
18824 <returnvalue>boolean
</returnvalue>
18827 Do the ranges overlap, that is, have any elements in common?
18830 <literal>int8range(
3,
7)
&& int8range(
4,
12)
</literal>
18831 <returnvalue>t
</returnvalue>
18836 <entry role=
"func_table_entry"><para role=
"func_signature">
18837 <type>anyrange
</type> <literal><<</literal> <type>anyrange
</type>
18838 <returnvalue>boolean
</returnvalue>
18841 Is the first range strictly left of the second?
18844 <literal>int8range(
1,
10)
<< int8range(
100,
110)
</literal>
18845 <returnvalue>t
</returnvalue>
18850 <entry role=
"func_table_entry"><para role=
"func_signature">
18851 <type>anyrange
</type> <literal>>></literal> <type>anyrange
</type>
18852 <returnvalue>boolean
</returnvalue>
18855 Is the first range strictly right of the second?
18858 <literal>int8range(
50,
60)
>> int8range(
20,
30)
</literal>
18859 <returnvalue>t
</returnvalue>
18864 <entry role=
"func_table_entry"><para role=
"func_signature">
18865 <type>anyrange
</type> <literal>&<</literal> <type>anyrange
</type>
18866 <returnvalue>boolean
</returnvalue>
18869 Does the first range not extend to the right of the second?
18872 <literal>int8range(
1,
20)
&< int8range(
18,
20)
</literal>
18873 <returnvalue>t
</returnvalue>
18878 <entry role=
"func_table_entry"><para role=
"func_signature">
18879 <type>anyrange
</type> <literal>&></literal> <type>anyrange
</type>
18880 <returnvalue>boolean
</returnvalue>
18883 Does the first range not extend to the left of the second?
18886 <literal>int8range(
7,
20)
&> int8range(
5,
10)
</literal>
18887 <returnvalue>t
</returnvalue>
18892 <entry role=
"func_table_entry"><para role=
"func_signature">
18893 <type>anyrange
</type> <literal>-|-
</literal> <type>anyrange
</type>
18894 <returnvalue>boolean
</returnvalue>
18897 Are the ranges adjacent?
18900 <literal>numrange(
1.1,
2.2) -|- numrange(
2.2,
3.3)
</literal>
18901 <returnvalue>t
</returnvalue>
18906 <entry role=
"func_table_entry"><para role=
"func_signature">
18907 <type>anyrange
</type> <literal>+
</literal> <type>anyrange
</type>
18908 <returnvalue>anyrange
</returnvalue>
18911 Computes the union of the ranges. The ranges must overlap or be
18912 adjacent, so that the union is a single range (but
18913 see
<function>range_merge()
</function>).
18916 <literal>numrange(
5,
15) + numrange(
10,
20)
</literal>
18917 <returnvalue>[
5,
20)
</returnvalue>
18922 <entry role=
"func_table_entry"><para role=
"func_signature">
18923 <type>anyrange
</type> <literal>*
</literal> <type>anyrange
</type>
18924 <returnvalue>anyrange
</returnvalue>
18927 Computes the intersection of the ranges.
18930 <literal>int8range(
5,
15) * int8range(
10,
20)
</literal>
18931 <returnvalue>[
10,
15)
</returnvalue>
18936 <entry role=
"func_table_entry"><para role=
"func_signature">
18937 <type>anyrange
</type> <literal>-
</literal> <type>anyrange
</type>
18938 <returnvalue>anyrange
</returnvalue>
18941 Computes the difference of the ranges. The second range must not be
18942 contained in the first in such a way that the difference would not be
18946 <literal>int8range(
5,
15) - int8range(
10,
20)
</literal>
18947 <returnvalue>[
5,
10)
</returnvalue>
18954 <table id=
"multirange-operators-table">
18955 <title>Multirange Operators
</title>
18959 <entry role=
"func_table_entry"><para role=
"func_signature">
18973 <entry role=
"func_table_entry"><para role=
"func_signature">
18974 <type>anymultirange
</type> <literal>@
></literal> <type>anymultirange
</type>
18975 <returnvalue>boolean
</returnvalue>
18978 Does the first multirange contain the second?
18981 <literal>'{[
2,
4)}'::int4multirange @
> '{[
2,
3)}'::int4multirange
</literal>
18982 <returnvalue>t
</returnvalue>
18987 <entry role=
"func_table_entry"><para role=
"func_signature">
18988 <type>anymultirange
</type> <literal>@
></literal> <type>anyrange
</type>
18989 <returnvalue>boolean
</returnvalue>
18992 Does the multirange contain the range?
18995 <literal>'{[
2,
4)}'::int4multirange @
> int4range(
2,
3)
</literal>
18996 <returnvalue>t
</returnvalue>
19001 <entry role=
"func_table_entry"><para role=
"func_signature">
19002 <type>anymultirange
</type> <literal>@
></literal> <type>anyelement
</type>
19003 <returnvalue>boolean
</returnvalue>
19006 Does the multirange contain the element?
19009 <literal>'{[
2011-
01-
01,
2011-
03-
01)}'::tsmultirange @
> '
2011-
01-
10'::timestamp
</literal>
19010 <returnvalue>t
</returnvalue>
19015 <entry role=
"func_table_entry"><para role=
"func_signature">
19016 <type>anyrange
</type> <literal>@
></literal> <type>anymultirange
</type>
19017 <returnvalue>boolean
</returnvalue>
19020 Does the range contain the multirange?
19023 <literal>'[
2,
4)'::int4range @
> '{[
2,
3)}'::int4multirange
</literal>
19024 <returnvalue>t
</returnvalue>
19029 <entry role=
"func_table_entry"><para role=
"func_signature">
19030 <type>anymultirange
</type> <literal><@
</literal> <type>anymultirange
</type>
19031 <returnvalue>boolean
</returnvalue>
19034 Is the first multirange contained by the second?
19037 <literal>'{[
2,
4)}'::int4multirange
<@ '{[
1,
7)}'::int4multirange
</literal>
19038 <returnvalue>t
</returnvalue>
19043 <entry role=
"func_table_entry"><para role=
"func_signature">
19044 <type>anymultirange
</type> <literal><@
</literal> <type>anyrange
</type>
19045 <returnvalue>boolean
</returnvalue>
19048 Is the multirange contained by the range?
19051 <literal>'{[
2,
4)}'::int4multirange
<@ int4range(
1,
7)
</literal>
19052 <returnvalue>t
</returnvalue>
19057 <entry role=
"func_table_entry"><para role=
"func_signature">
19058 <type>anyrange
</type> <literal><@
</literal> <type>anymultirange
</type>
19059 <returnvalue>boolean
</returnvalue>
19062 Is the range contained by the multirange?
19065 <literal>int4range(
2,
4)
<@ '{[
1,
7)}'::int4multirange
</literal>
19066 <returnvalue>t
</returnvalue>
19071 <entry role=
"func_table_entry"><para role=
"func_signature">
19072 <type>anyelement
</type> <literal><@
</literal> <type>anymultirange
</type>
19073 <returnvalue>boolean
</returnvalue>
19076 Is the element contained by the multirange?
19079 <literal>4 <@ '{[
1,
7)}'::int4multirange
</literal>
19080 <returnvalue>t
</returnvalue>
19085 <entry role=
"func_table_entry"><para role=
"func_signature">
19086 <type>anymultirange
</type> <literal>&&</literal> <type>anymultirange
</type>
19087 <returnvalue>boolean
</returnvalue>
19090 Do the multiranges overlap, that is, have any elements in common?
19093 <literal>'{[
3,
7)}'::int8multirange
&& '{[
4,
12)}'::int8multirange
</literal>
19094 <returnvalue>t
</returnvalue>
19099 <entry role=
"func_table_entry"><para role=
"func_signature">
19100 <type>anymultirange
</type> <literal>&&</literal> <type>anyrange
</type>
19101 <returnvalue>boolean
</returnvalue>
19104 Does the multirange overlap the range?
19107 <literal>'{[
3,
7)}'::int8multirange
&& int8range(
4,
12)
</literal>
19108 <returnvalue>t
</returnvalue>
19113 <entry role=
"func_table_entry"><para role=
"func_signature">
19114 <type>anyrange
</type> <literal>&&</literal> <type>anymultirange
</type>
19115 <returnvalue>boolean
</returnvalue>
19118 Does the range overlap the multirange?
19121 <literal>int8range(
3,
7)
&& '{[
4,
12)}'::int8multirange
</literal>
19122 <returnvalue>t
</returnvalue>
19127 <entry role=
"func_table_entry"><para role=
"func_signature">
19128 <type>anymultirange
</type> <literal><<</literal> <type>anymultirange
</type>
19129 <returnvalue>boolean
</returnvalue>
19132 Is the first multirange strictly left of the second?
19135 <literal>'{[
1,
10)}'::int8multirange
<< '{[
100,
110)}'::int8multirange
</literal>
19136 <returnvalue>t
</returnvalue>
19141 <entry role=
"func_table_entry"><para role=
"func_signature">
19142 <type>anymultirange
</type> <literal><<</literal> <type>anyrange
</type>
19143 <returnvalue>boolean
</returnvalue>
19146 Is the multirange strictly left of the range?
19149 <literal>'{[
1,
10)}'::int8multirange
<< int8range(
100,
110)
</literal>
19150 <returnvalue>t
</returnvalue>
19155 <entry role=
"func_table_entry"><para role=
"func_signature">
19156 <type>anyrange
</type> <literal><<</literal> <type>anymultirange
</type>
19157 <returnvalue>boolean
</returnvalue>
19160 Is the range strictly left of the multirange?
19163 <literal>int8range(
1,
10)
<< '{[
100,
110)}'::int8multirange
</literal>
19164 <returnvalue>t
</returnvalue>
19169 <entry role=
"func_table_entry"><para role=
"func_signature">
19170 <type>anymultirange
</type> <literal>>></literal> <type>anymultirange
</type>
19171 <returnvalue>boolean
</returnvalue>
19174 Is the first multirange strictly right of the second?
19177 <literal>'{[
50,
60)}'::int8multirange
>> '{[
20,
30)}'::int8multirange
</literal>
19178 <returnvalue>t
</returnvalue>
19183 <entry role=
"func_table_entry"><para role=
"func_signature">
19184 <type>anymultirange
</type> <literal>>></literal> <type>anyrange
</type>
19185 <returnvalue>boolean
</returnvalue>
19188 Is the multirange strictly right of the range?
19191 <literal>'{[
50,
60)}'::int8multirange
>> int8range(
20,
30)
</literal>
19192 <returnvalue>t
</returnvalue>
19197 <entry role=
"func_table_entry"><para role=
"func_signature">
19198 <type>anyrange
</type> <literal>>></literal> <type>anymultirange
</type>
19199 <returnvalue>boolean
</returnvalue>
19202 Is the range strictly right of the multirange?
19205 <literal>int8range(
50,
60)
>> '{[
20,
30)}'::int8multirange
</literal>
19206 <returnvalue>t
</returnvalue>
19211 <entry role=
"func_table_entry"><para role=
"func_signature">
19212 <type>anymultirange
</type> <literal>&<</literal> <type>anymultirange
</type>
19213 <returnvalue>boolean
</returnvalue>
19216 Does the first multirange not extend to the right of the second?
19219 <literal>'{[
1,
20)}'::int8multirange
&< '{[
18,
20)}'::int8multirange
</literal>
19220 <returnvalue>t
</returnvalue>
19225 <entry role=
"func_table_entry"><para role=
"func_signature">
19226 <type>anymultirange
</type> <literal>&<</literal> <type>anyrange
</type>
19227 <returnvalue>boolean
</returnvalue>
19230 Does the multirange not extend to the right of the range?
19233 <literal>'{[
1,
20)}'::int8multirange
&< int8range(
18,
20)
</literal>
19234 <returnvalue>t
</returnvalue>
19239 <entry role=
"func_table_entry"><para role=
"func_signature">
19240 <type>anyrange
</type> <literal>&<</literal> <type>anymultirange
</type>
19241 <returnvalue>boolean
</returnvalue>
19244 Does the range not extend to the right of the multirange?
19247 <literal>int8range(
1,
20)
&< '{[
18,
20)}'::int8multirange
</literal>
19248 <returnvalue>t
</returnvalue>
19253 <entry role=
"func_table_entry"><para role=
"func_signature">
19254 <type>anymultirange
</type> <literal>&></literal> <type>anymultirange
</type>
19255 <returnvalue>boolean
</returnvalue>
19258 Does the first multirange not extend to the left of the second?
19261 <literal>'{[
7,
20)}'::int8multirange
&> '{[
5,
10)}'::int8multirange
</literal>
19262 <returnvalue>t
</returnvalue>
19267 <entry role=
"func_table_entry"><para role=
"func_signature">
19268 <type>anymultirange
</type> <literal>&></literal> <type>anyrange
</type>
19269 <returnvalue>boolean
</returnvalue>
19272 Does the multirange not extend to the left of the range?
19275 <literal>'{[
7,
20)}'::int8multirange
&> int8range(
5,
10)
</literal>
19276 <returnvalue>t
</returnvalue>
19281 <entry role=
"func_table_entry"><para role=
"func_signature">
19282 <type>anyrange
</type> <literal>&></literal> <type>anymultirange
</type>
19283 <returnvalue>boolean
</returnvalue>
19286 Does the range not extend to the left of the multirange?
19289 <literal>int8range(
7,
20)
&> '{[
5,
10)}'::int8multirange
</literal>
19290 <returnvalue>t
</returnvalue>
19295 <entry role=
"func_table_entry"><para role=
"func_signature">
19296 <type>anymultirange
</type> <literal>-|-
</literal> <type>anymultirange
</type>
19297 <returnvalue>boolean
</returnvalue>
19300 Are the multiranges adjacent?
19303 <literal>'{[
1.1,
2.2)}'::nummultirange -|- '{[
2.2,
3.3)}'::nummultirange
</literal>
19304 <returnvalue>t
</returnvalue>
19309 <entry role=
"func_table_entry"><para role=
"func_signature">
19310 <type>anymultirange
</type> <literal>-|-
</literal> <type>anyrange
</type>
19311 <returnvalue>boolean
</returnvalue>
19314 Is the multirange adjacent to the range?
19317 <literal>'{[
1.1,
2.2)}'::nummultirange -|- numrange(
2.2,
3.3)
</literal>
19318 <returnvalue>t
</returnvalue>
19323 <entry role=
"func_table_entry"><para role=
"func_signature">
19324 <type>anyrange
</type> <literal>-|-
</literal> <type>anymultirange
</type>
19325 <returnvalue>boolean
</returnvalue>
19328 Is the range adjacent to the multirange?
19331 <literal>numrange(
1.1,
2.2) -|- '{[
2.2,
3.3)}'::nummultirange
</literal>
19332 <returnvalue>t
</returnvalue>
19337 <entry role=
"func_table_entry"><para role=
"func_signature">
19338 <type>anymultirange
</type> <literal>+
</literal> <type>anymultirange
</type>
19339 <returnvalue>anymultirange
</returnvalue>
19342 Computes the union of the multiranges. The multiranges need not overlap
19346 <literal>'{[
5,
10)}'::nummultirange + '{[
15,
20)}'::nummultirange
</literal>
19347 <returnvalue>{[
5,
10), [
15,
20)}
</returnvalue>
19352 <entry role=
"func_table_entry"><para role=
"func_signature">
19353 <type>anymultirange
</type> <literal>*
</literal> <type>anymultirange
</type>
19354 <returnvalue>anymultirange
</returnvalue>
19357 Computes the intersection of the multiranges.
19360 <literal>'{[
5,
15)}'::int8multirange * '{[
10,
20)}'::int8multirange
</literal>
19361 <returnvalue>{[
10,
15)}
</returnvalue>
19366 <entry role=
"func_table_entry"><para role=
"func_signature">
19367 <type>anymultirange
</type> <literal>-
</literal> <type>anymultirange
</type>
19368 <returnvalue>anymultirange
</returnvalue>
19371 Computes the difference of the multiranges.
19374 <literal>'{[
5,
20)}'::int8multirange - '{[
10,
15)}'::int8multirange
</literal>
19375 <returnvalue>{[
5,
10), [
15,
20)}
</returnvalue>
19383 The left-of/right-of/adjacent operators always return false when an empty
19384 range or multirange is involved; that is, an empty range is not considered to
19385 be either before or after any other range.
19389 Elsewhere empty ranges and multiranges are treated as the additive identity:
19390 anything unioned with an empty value is itself. Anything minus an empty
19391 value is itself. An empty multirange has exactly the same points as an empty
19392 range. Every range contains the empty range. Every multirange contains as many
19393 empty ranges as you like.
19397 The range union and difference operators will fail if the resulting range would
19398 need to contain two disjoint sub-ranges, as such a range cannot be
19399 represented. There are separate operators for union and difference that take
19400 multirange parameters and return a multirange, and they do not fail even if
19401 their arguments are disjoint. So if you need a union or difference operation
19402 for ranges that may be disjoint, you can avoid errors by first casting your
19403 ranges to multiranges.
19407 <xref linkend=
"range-functions-table"/> shows the functions
19408 available for use with range types.
19409 <xref linkend=
"multirange-functions-table"/> shows the functions
19410 available for use with multirange types.
19413 <table id=
"range-functions-table">
19414 <title>Range Functions
</title>
19418 <entry role=
"func_table_entry"><para role=
"func_signature">
19432 <entry role=
"func_table_entry"><para role=
"func_signature">
19434 <primary>lower
</primary>
19436 <function>lower
</function> (
<type>anyrange
</type> )
19437 <returnvalue>anyelement
</returnvalue>
19440 Extracts the lower bound of the range (
<literal>NULL
</literal> if the
19441 range is empty or the lower bound is infinite).
19444 <literal>lower(numrange(
1.1,
2.2))
</literal>
19445 <returnvalue>1.1</returnvalue>
19450 <entry role=
"func_table_entry"><para role=
"func_signature">
19452 <primary>upper
</primary>
19454 <function>upper
</function> (
<type>anyrange
</type> )
19455 <returnvalue>anyelement
</returnvalue>
19458 Extracts the upper bound of the range (
<literal>NULL
</literal> if the
19459 range is empty or the upper bound is infinite).
19462 <literal>upper(numrange(
1.1,
2.2))
</literal>
19463 <returnvalue>2.2</returnvalue>
19468 <entry role=
"func_table_entry"><para role=
"func_signature">
19470 <primary>isempty
</primary>
19472 <function>isempty
</function> (
<type>anyrange
</type> )
19473 <returnvalue>boolean
</returnvalue>
19476 Is the range empty?
19479 <literal>isempty(numrange(
1.1,
2.2))
</literal>
19480 <returnvalue>f
</returnvalue>
19485 <entry role=
"func_table_entry"><para role=
"func_signature">
19487 <primary>lower_inc
</primary>
19489 <function>lower_inc
</function> (
<type>anyrange
</type> )
19490 <returnvalue>boolean
</returnvalue>
19493 Is the range's lower bound inclusive?
19496 <literal>lower_inc(numrange(
1.1,
2.2))
</literal>
19497 <returnvalue>t
</returnvalue>
19502 <entry role=
"func_table_entry"><para role=
"func_signature">
19504 <primary>upper_inc
</primary>
19506 <function>upper_inc
</function> (
<type>anyrange
</type> )
19507 <returnvalue>boolean
</returnvalue>
19510 Is the range's upper bound inclusive?
19513 <literal>upper_inc(numrange(
1.1,
2.2))
</literal>
19514 <returnvalue>f
</returnvalue>
19519 <entry role=
"func_table_entry"><para role=
"func_signature">
19521 <primary>lower_inf
</primary>
19523 <function>lower_inf
</function> (
<type>anyrange
</type> )
19524 <returnvalue>boolean
</returnvalue>
19527 Is the range's lower bound infinite?
19530 <literal>lower_inf('(,)'::daterange)
</literal>
19531 <returnvalue>t
</returnvalue>
19536 <entry role=
"func_table_entry"><para role=
"func_signature">
19538 <primary>upper_inf
</primary>
19540 <function>upper_inf
</function> (
<type>anyrange
</type> )
19541 <returnvalue>boolean
</returnvalue>
19544 Is the range's upper bound infinite?
19547 <literal>upper_inf('(,)'::daterange)
</literal>
19548 <returnvalue>t
</returnvalue>
19553 <entry role=
"func_table_entry"><para role=
"func_signature">
19555 <primary>range_merge
</primary>
19557 <function>range_merge
</function> (
<type>anyrange
</type>,
<type>anyrange
</type> )
19558 <returnvalue>anyrange
</returnvalue>
19561 Computes the smallest range that includes both of the given ranges.
19564 <literal>range_merge('[
1,
2)'::int4range, '[
3,
4)'::int4range)
</literal>
19565 <returnvalue>[
1,
4)
</returnvalue>
19572 <table id=
"multirange-functions-table">
19573 <title>Multirange Functions
</title>
19577 <entry role=
"func_table_entry"><para role=
"func_signature">
19590 <entry role=
"func_table_entry"><para role=
"func_signature">
19592 <primary>lower
</primary>
19594 <function>lower
</function> (
<type>anymultirange
</type> )
19595 <returnvalue>anyelement
</returnvalue>
19598 Extracts the lower bound of the multirange (
<literal>NULL
</literal> if the
19599 multirange is empty or the lower bound is infinite).
19602 <literal>lower('{[
1.1,
2.2)}'::nummultirange)
</literal>
19603 <returnvalue>1.1</returnvalue>
19608 <entry role=
"func_table_entry"><para role=
"func_signature">
19610 <primary>upper
</primary>
19612 <function>upper
</function> (
<type>anymultirange
</type> )
19613 <returnvalue>anyelement
</returnvalue>
19616 Extracts the upper bound of the multirange (
<literal>NULL
</literal> if the
19617 multirange is empty or the upper bound is infinite).
19620 <literal>upper('{[
1.1,
2.2)}'::nummultirange)
</literal>
19621 <returnvalue>2.2</returnvalue>
19626 <entry role=
"func_table_entry"><para role=
"func_signature">
19628 <primary>isempty
</primary>
19630 <function>isempty
</function> (
<type>anymultirange
</type> )
19631 <returnvalue>boolean
</returnvalue>
19634 Is the multirange empty?
19637 <literal>isempty('{[
1.1,
2.2)}'::nummultirange)
</literal>
19638 <returnvalue>f
</returnvalue>
19643 <entry role=
"func_table_entry"><para role=
"func_signature">
19645 <primary>lower_inc
</primary>
19647 <function>lower_inc
</function> (
<type>anymultirange
</type> )
19648 <returnvalue>boolean
</returnvalue>
19651 Is the multirange's lower bound inclusive?
19654 <literal>lower_inc('{[
1.1,
2.2)}'::nummultirange)
</literal>
19655 <returnvalue>t
</returnvalue>
19660 <entry role=
"func_table_entry"><para role=
"func_signature">
19662 <primary>upper_inc
</primary>
19664 <function>upper_inc
</function> (
<type>anymultirange
</type> )
19665 <returnvalue>boolean
</returnvalue>
19668 Is the multirange's upper bound inclusive?
19671 <literal>upper_inc('{[
1.1,
2.2)}'::nummultirange)
</literal>
19672 <returnvalue>f
</returnvalue>
19677 <entry role=
"func_table_entry"><para role=
"func_signature">
19679 <primary>lower_inf
</primary>
19681 <function>lower_inf
</function> (
<type>anymultirange
</type> )
19682 <returnvalue>boolean
</returnvalue>
19685 Is the multirange's lower bound infinite?
19688 <literal>lower_inf('{(,)}'::datemultirange)
</literal>
19689 <returnvalue>t
</returnvalue>
19694 <entry role=
"func_table_entry"><para role=
"func_signature">
19696 <primary>upper_inf
</primary>
19698 <function>upper_inf
</function> (
<type>anymultirange
</type> )
19699 <returnvalue>boolean
</returnvalue>
19702 Is the multirange's upper bound infinite?
19705 <literal>upper_inf('{(,)}'::datemultirange)
</literal>
19706 <returnvalue>t
</returnvalue>
19711 <entry role=
"func_table_entry"><para role=
"func_signature">
19713 <primary>range_merge
</primary>
19715 <function>range_merge
</function> (
<type>anymultirange
</type> )
19716 <returnvalue>anyrange
</returnvalue>
19719 Computes the smallest range that includes the entire multirange.
19722 <literal>range_merge('{[
1,
2), [
3,
4)}'::int4multirange)
</literal>
19723 <returnvalue>[
1,
4)
</returnvalue>
19728 <entry role=
"func_table_entry"><para role=
"func_signature">
19730 <primary>multirange (function)
</primary>
19732 <function>multirange
</function> (
<type>anyrange
</type> )
19733 <returnvalue>anymultirange
</returnvalue>
19736 Returns a multirange containing just the given range.
19739 <literal>multirange('[
1,
2)'::int4range)
</literal>
19740 <returnvalue>{[
1,
2)}
</returnvalue>
19745 <entry role=
"func_table_entry"><para role=
"func_signature">
19747 <primary>unnest
</primary>
19748 <secondary>for multirange
</secondary>
19750 <function>unnest
</function> (
<type>anymultirange
</type> )
19751 <returnvalue>setof anyrange
</returnvalue>
19754 Expands a multirange into a set of ranges.
19755 The ranges are read out in storage order (ascending).
19758 <literal>unnest('{[
1,
2), [
3,
4)}'::int4multirange)
</literal>
19759 <returnvalue></returnvalue>
19771 The
<function>lower_inc
</function>,
<function>upper_inc
</function>,
19772 <function>lower_inf
</function>, and
<function>upper_inf
</function>
19773 functions all return false for an empty range or multirange.
19777 <sect1 id=
"functions-aggregate">
19778 <title>Aggregate Functions
</title>
19780 <indexterm zone=
"functions-aggregate">
19781 <primary>aggregate function
</primary>
19782 <secondary>built-in
</secondary>
19786 <firstterm>Aggregate functions
</firstterm> compute a single result
19787 from a set of input values. The built-in general-purpose aggregate
19788 functions are listed in
<xref linkend=
"functions-aggregate-table"/>
19789 while statistical aggregates are in
<xref
19790 linkend=
"functions-aggregate-statistics-table"/>.
19791 The built-in within-group ordered-set aggregate functions
19792 are listed in
<xref linkend=
"functions-orderedset-table"/>
19793 while the built-in within-group hypothetical-set ones are in
<xref
19794 linkend=
"functions-hypothetical-table"/>. Grouping operations,
19795 which are closely related to aggregate functions, are listed in
19796 <xref linkend=
"functions-grouping-table"/>.
19797 The special syntax considerations for aggregate
19798 functions are explained in
<xref linkend=
"syntax-aggregates"/>.
19799 Consult
<xref linkend=
"tutorial-agg"/> for additional introductory
19804 Aggregate functions that support
<firstterm>Partial Mode
</firstterm>
19805 are eligible to participate in various optimizations, such as parallel
19809 <table id=
"functions-aggregate-table">
19810 <title>General-Purpose Aggregate Functions
</title>
19812 <colspec colname=
"col1" colwidth=
"10*"/>
19813 <colspec colname=
"col2" colwidth=
"1*"/>
19816 <entry role=
"func_table_entry"><para role=
"func_signature">
19822 <entry>Partial Mode
</entry>
19828 <entry role=
"func_table_entry"><para role=
"func_signature">
19830 <primary>any_value
</primary>
19832 <function>any_value
</function> (
<type>anyelement
</type> )
19833 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
19836 Returns an arbitrary value from the non-null input values.
19842 <entry role=
"func_table_entry"><para role=
"func_signature">
19844 <primary>array_agg
</primary>
19846 <function>array_agg
</function> (
<type>anynonarray
</type> )
19847 <returnvalue>anyarray
</returnvalue>
19850 Collects all the input values, including nulls, into an array.
19856 <entry role=
"func_table_entry"><para role=
"func_signature">
19857 <function>array_agg
</function> (
<type>anyarray
</type> )
19858 <returnvalue>anyarray
</returnvalue>
19861 Concatenates all the input arrays into an array of one higher
19862 dimension. (The inputs must all have the same dimensionality, and
19863 cannot be empty or null.)
19869 <entry role=
"func_table_entry"><para role=
"func_signature">
19871 <primary>average
</primary>
19874 <primary>avg
</primary>
19876 <function>avg
</function> (
<type>smallint
</type> )
19877 <returnvalue>numeric
</returnvalue>
19879 <para role=
"func_signature">
19880 <function>avg
</function> (
<type>integer
</type> )
19881 <returnvalue>numeric
</returnvalue>
19883 <para role=
"func_signature">
19884 <function>avg
</function> (
<type>bigint
</type> )
19885 <returnvalue>numeric
</returnvalue>
19887 <para role=
"func_signature">
19888 <function>avg
</function> (
<type>numeric
</type> )
19889 <returnvalue>numeric
</returnvalue>
19891 <para role=
"func_signature">
19892 <function>avg
</function> (
<type>real
</type> )
19893 <returnvalue>double precision
</returnvalue>
19895 <para role=
"func_signature">
19896 <function>avg
</function> (
<type>double precision
</type> )
19897 <returnvalue>double precision
</returnvalue>
19899 <para role=
"func_signature">
19900 <function>avg
</function> (
<type>interval
</type> )
19901 <returnvalue>interval
</returnvalue>
19904 Computes the average (arithmetic mean) of all the non-null input
19911 <entry role=
"func_table_entry"><para role=
"func_signature">
19913 <primary>bit_and
</primary>
19915 <function>bit_and
</function> (
<type>smallint
</type> )
19916 <returnvalue>smallint
</returnvalue>
19918 <para role=
"func_signature">
19919 <function>bit_and
</function> (
<type>integer
</type> )
19920 <returnvalue>integer
</returnvalue>
19922 <para role=
"func_signature">
19923 <function>bit_and
</function> (
<type>bigint
</type> )
19924 <returnvalue>bigint
</returnvalue>
19926 <para role=
"func_signature">
19927 <function>bit_and
</function> (
<type>bit
</type> )
19928 <returnvalue>bit
</returnvalue>
19931 Computes the bitwise AND of all non-null input values.
19937 <entry role=
"func_table_entry"><para role=
"func_signature">
19939 <primary>bit_or
</primary>
19941 <function>bit_or
</function> (
<type>smallint
</type> )
19942 <returnvalue>smallint
</returnvalue>
19944 <para role=
"func_signature">
19945 <function>bit_or
</function> (
<type>integer
</type> )
19946 <returnvalue>integer
</returnvalue>
19948 <para role=
"func_signature">
19949 <function>bit_or
</function> (
<type>bigint
</type> )
19950 <returnvalue>bigint
</returnvalue>
19952 <para role=
"func_signature">
19953 <function>bit_or
</function> (
<type>bit
</type> )
19954 <returnvalue>bit
</returnvalue>
19957 Computes the bitwise OR of all non-null input values.
19963 <entry role=
"func_table_entry"><para role=
"func_signature">
19965 <primary>bit_xor
</primary>
19967 <function>bit_xor
</function> (
<type>smallint
</type> )
19968 <returnvalue>smallint
</returnvalue>
19970 <para role=
"func_signature">
19971 <function>bit_xor
</function> (
<type>integer
</type> )
19972 <returnvalue>integer
</returnvalue>
19974 <para role=
"func_signature">
19975 <function>bit_xor
</function> (
<type>bigint
</type> )
19976 <returnvalue>bigint
</returnvalue>
19978 <para role=
"func_signature">
19979 <function>bit_xor
</function> (
<type>bit
</type> )
19980 <returnvalue>bit
</returnvalue>
19983 Computes the bitwise exclusive OR of all non-null input values.
19984 Can be useful as a checksum for an unordered set of values.
19990 <entry role=
"func_table_entry"><para role=
"func_signature">
19992 <primary>bool_and
</primary>
19994 <function>bool_and
</function> (
<type>boolean
</type> )
19995 <returnvalue>boolean
</returnvalue>
19998 Returns true if all non-null input values are true, otherwise false.
20004 <entry role=
"func_table_entry"><para role=
"func_signature">
20006 <primary>bool_or
</primary>
20008 <function>bool_or
</function> (
<type>boolean
</type> )
20009 <returnvalue>boolean
</returnvalue>
20012 Returns true if any non-null input value is true, otherwise false.
20018 <entry role=
"func_table_entry"><para role=
"func_signature">
20020 <primary>count
</primary>
20022 <function>count
</function> (
<literal>*
</literal> )
20023 <returnvalue>bigint
</returnvalue>
20026 Computes the number of input rows.
20032 <entry role=
"func_table_entry"><para role=
"func_signature">
20033 <function>count
</function> (
<type>"any"</type> )
20034 <returnvalue>bigint
</returnvalue>
20037 Computes the number of input rows in which the input value is not
20044 <entry role=
"func_table_entry"><para role=
"func_signature">
20046 <primary>every
</primary>
20048 <function>every
</function> (
<type>boolean
</type> )
20049 <returnvalue>boolean
</returnvalue>
20052 This is the SQL standard's equivalent to
<function>bool_and
</function>.
20058 <entry role=
"func_table_entry"><para role=
"func_signature">
20060 <primary>json_agg
</primary>
20062 <function>json_agg
</function> (
<type>anyelement
</type> )
20063 <returnvalue>json
</returnvalue>
20065 <para role=
"func_signature">
20067 <primary>jsonb_agg
</primary>
20069 <function>jsonb_agg
</function> (
<type>anyelement
</type> )
20070 <returnvalue>jsonb
</returnvalue>
20073 Collects all the input values, including nulls, into a JSON array.
20074 Values are converted to JSON as per
<function>to_json
</function>
20075 or
<function>to_jsonb
</function>.
20081 <entry role=
"func_table_entry"><para role=
"func_signature">
20083 <primary>json_object_agg
</primary>
20085 <function>json_object_agg
</function> (
<parameter>key
</parameter>
20086 <type>"any"</type>,
<parameter>value
</parameter>
20087 <type>"any"</type> )
20088 <returnvalue>json
</returnvalue>
20090 <para role=
"func_signature">
20092 <primary>jsonb_object_agg
</primary>
20094 <function>jsonb_object_agg
</function> (
<parameter>key
</parameter>
20095 <type>"any"</type>,
<parameter>value
</parameter>
20096 <type>"any"</type> )
20097 <returnvalue>jsonb
</returnvalue>
20100 Collects all the key/value pairs into a JSON object. Key arguments
20101 are coerced to text; value arguments are converted as
20102 per
<function>to_json
</function> or
<function>to_jsonb
</function>.
20103 Values can be null, but not keys.
20109 <entry role=
"func_table_entry"><para role=
"func_signature">
20111 <primary>max
</primary>
20113 <function>max
</function> (
<replaceable>see text
</replaceable> )
20114 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
20117 Computes the maximum of the non-null input
20118 values. Available for any numeric, string, date/time, or enum type,
20119 as well as
<type>inet
</type>,
<type>interval
</type>,
20120 <type>money
</type>,
<type>oid
</type>,
<type>pg_lsn
</type>,
20121 <type>tid
</type>,
<type>xid8
</type>,
20122 and arrays of any of these types.
20128 <entry role=
"func_table_entry"><para role=
"func_signature">
20130 <primary>min
</primary>
20132 <function>min
</function> (
<replaceable>see text
</replaceable> )
20133 <returnvalue><replaceable>same as input type
</replaceable></returnvalue>
20136 Computes the minimum of the non-null input
20137 values. Available for any numeric, string, date/time, or enum type,
20138 as well as
<type>inet
</type>,
<type>interval
</type>,
20139 <type>money
</type>,
<type>oid
</type>,
<type>pg_lsn
</type>,
20140 <type>tid
</type>,
<type>xid8
</type>,
20141 and arrays of any of these types.
20147 <entry role=
"func_table_entry"><para role=
"func_signature">
20149 <primary>range_agg
</primary>
20151 <function>range_agg
</function> (
<parameter>value
</parameter>
20152 <type>anyrange
</type> )
20153 <returnvalue>anymultirange
</returnvalue>
20155 <para role=
"func_signature">
20156 <function>range_agg
</function> (
<parameter>value
</parameter>
20157 <type>anymultirange
</type> )
20158 <returnvalue>anymultirange
</returnvalue>
20161 Computes the union of the non-null input values.
20167 <entry role=
"func_table_entry"><para role=
"func_signature">
20169 <primary>range_intersect_agg
</primary>
20171 <function>range_intersect_agg
</function> (
<parameter>value
</parameter>
20172 <type>anyrange
</type> )
20173 <returnvalue>anyrange
</returnvalue>
20175 <para role=
"func_signature">
20176 <function>range_intersect_agg
</function> (
<parameter>value
</parameter>
20177 <type>anymultirange
</type> )
20178 <returnvalue>anymultirange
</returnvalue>
20181 Computes the intersection of the non-null input values.
20187 <entry role=
"func_table_entry"><para role=
"func_signature">
20189 <primary>string_agg
</primary>
20191 <function>string_agg
</function> (
<parameter>value
</parameter>
20192 <type>text
</type>,
<parameter>delimiter
</parameter> <type>text
</type> )
20193 <returnvalue>text
</returnvalue>
20195 <para role=
"func_signature">
20196 <function>string_agg
</function> (
<parameter>value
</parameter>
20197 <type>bytea
</type>,
<parameter>delimiter
</parameter> <type>bytea
</type> )
20198 <returnvalue>bytea
</returnvalue>
20201 Concatenates the non-null input values into a string. Each value
20202 after the first is preceded by the
20203 corresponding
<parameter>delimiter
</parameter> (if it's not null).
20209 <entry role=
"func_table_entry"><para role=
"func_signature">
20211 <primary>sum
</primary>
20213 <function>sum
</function> (
<type>smallint
</type> )
20214 <returnvalue>bigint
</returnvalue>
20216 <para role=
"func_signature">
20217 <function>sum
</function> (
<type>integer
</type> )
20218 <returnvalue>bigint
</returnvalue>
20220 <para role=
"func_signature">
20221 <function>sum
</function> (
<type>bigint
</type> )
20222 <returnvalue>numeric
</returnvalue>
20224 <para role=
"func_signature">
20225 <function>sum
</function> (
<type>numeric
</type> )
20226 <returnvalue>numeric
</returnvalue>
20228 <para role=
"func_signature">
20229 <function>sum
</function> (
<type>real
</type> )
20230 <returnvalue>real
</returnvalue>
20232 <para role=
"func_signature">
20233 <function>sum
</function> (
<type>double precision
</type> )
20234 <returnvalue>double precision
</returnvalue>
20236 <para role=
"func_signature">
20237 <function>sum
</function> (
<type>interval
</type> )
20238 <returnvalue>interval
</returnvalue>
20240 <para role=
"func_signature">
20241 <function>sum
</function> (
<type>money
</type> )
20242 <returnvalue>money
</returnvalue>
20245 Computes the sum of the non-null input values.
20251 <entry role=
"func_table_entry"><para role=
"func_signature">
20253 <primary>xmlagg
</primary>
20255 <function>xmlagg
</function> (
<type>xml
</type> )
20256 <returnvalue>xml
</returnvalue>
20259 Concatenates the non-null XML input values (see
20260 <xref linkend=
"functions-xml-xmlagg"/>).
20269 It should be noted that except for
<function>count
</function>,
20270 these functions return a null value when no rows are selected. In
20271 particular,
<function>sum
</function> of no rows returns null, not
20272 zero as one might expect, and
<function>array_agg
</function>
20273 returns null rather than an empty array when there are no input
20274 rows. The
<function>coalesce
</function> function can be used to
20275 substitute zero or an empty array for null when necessary.
20279 The aggregate functions
<function>array_agg
</function>,
20280 <function>json_agg
</function>,
<function>jsonb_agg
</function>,
20281 <function>json_object_agg
</function>,
<function>jsonb_object_agg
</function>,
20282 <function>string_agg
</function>,
20283 and
<function>xmlagg
</function>, as well as similar user-defined
20284 aggregate functions, produce meaningfully different result values
20285 depending on the order of the input values. This ordering is
20286 unspecified by default, but can be controlled by writing an
20287 <literal>ORDER BY
</literal> clause within the aggregate call, as shown in
20288 <xref linkend=
"syntax-aggregates"/>.
20289 Alternatively, supplying the input values from a sorted subquery
20290 will usually work. For example:
20293 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
20296 Beware that this approach can fail if the outer query level contains
20297 additional processing, such as a join, because that might cause the
20298 subquery's output to be reordered before the aggregate is computed.
20303 <primary>ANY
</primary>
20306 <primary>SOME
</primary>
20309 The boolean aggregates
<function>bool_and
</function> and
20310 <function>bool_or
</function> correspond to the standard SQL aggregates
20311 <function>every
</function> and
<function>any
</function> or
20312 <function>some
</function>.
20313 <productname>PostgreSQL
</productname>
20314 supports
<function>every
</function>, but not
<function>any
</function>
20315 or
<function>some
</function>, because there is an ambiguity built into
20316 the standard syntax:
20318 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
20320 Here
<function>ANY
</function> can be considered either as introducing
20321 a subquery, or as being an aggregate function, if the subquery
20322 returns one row with a Boolean value.
20323 Thus the standard name cannot be given to these aggregates.
20329 Users accustomed to working with other SQL database management
20330 systems might be disappointed by the performance of the
20331 <function>count
</function> aggregate when it is applied to the
20332 entire table. A query like:
20334 SELECT count(*) FROM sometable;
20336 will require effort proportional to the size of the table:
20337 <productname>PostgreSQL
</productname> will need to scan either the
20338 entire table or the entirety of an index that includes all rows in
20344 <xref linkend=
"functions-aggregate-statistics-table"/> shows
20345 aggregate functions typically used in statistical analysis.
20346 (These are separated out merely to avoid cluttering the listing
20347 of more-commonly-used aggregates.) Functions shown as
20348 accepting
<replaceable>numeric_type
</replaceable> are available for all
20349 the types
<type>smallint
</type>,
<type>integer
</type>,
20350 <type>bigint
</type>,
<type>numeric
</type>,
<type>real
</type>,
20351 and
<type>double precision
</type>.
20352 Where the description mentions
20353 <parameter>N
</parameter>, it means the
20354 number of input rows for which all the input expressions are non-null.
20355 In all cases, null is returned if the computation is meaningless,
20356 for example when
<parameter>N
</parameter> is zero.
20360 <primary>statistics
</primary>
20363 <primary>linear regression
</primary>
20366 <table id=
"functions-aggregate-statistics-table">
20367 <title>Aggregate Functions for Statistics
</title>
20369 <colspec colname=
"col1" colwidth=
"10*"/>
20370 <colspec colname=
"col2" colwidth=
"1*"/>
20373 <entry role=
"func_table_entry"><para role=
"func_signature">
20379 <entry>Partial Mode
</entry>
20385 <entry role=
"func_table_entry"><para role=
"func_signature">
20387 <primary>correlation
</primary>
20390 <primary>corr
</primary>
20392 <function>corr
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20393 <returnvalue>double precision
</returnvalue>
20396 Computes the correlation coefficient.
20402 <entry role=
"func_table_entry"><para role=
"func_signature">
20404 <primary>covariance
</primary>
20405 <secondary>population
</secondary>
20408 <primary>covar_pop
</primary>
20410 <function>covar_pop
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20411 <returnvalue>double precision
</returnvalue>
20414 Computes the population covariance.
20420 <entry role=
"func_table_entry"><para role=
"func_signature">
20422 <primary>covariance
</primary>
20423 <secondary>sample
</secondary>
20426 <primary>covar_samp
</primary>
20428 <function>covar_samp
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20429 <returnvalue>double precision
</returnvalue>
20432 Computes the sample covariance.
20438 <entry role=
"func_table_entry"><para role=
"func_signature">
20440 <primary>regr_avgx
</primary>
20442 <function>regr_avgx
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20443 <returnvalue>double precision
</returnvalue>
20446 Computes the average of the independent variable,
20447 <literal>sum(
<parameter>X
</parameter>)/
<parameter>N
</parameter></literal>.
20453 <entry role=
"func_table_entry"><para role=
"func_signature">
20455 <primary>regr_avgy
</primary>
20457 <function>regr_avgy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20458 <returnvalue>double precision
</returnvalue>
20461 Computes the average of the dependent variable,
20462 <literal>sum(
<parameter>Y
</parameter>)/
<parameter>N
</parameter></literal>.
20468 <entry role=
"func_table_entry"><para role=
"func_signature">
20470 <primary>regr_count
</primary>
20472 <function>regr_count
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20473 <returnvalue>bigint
</returnvalue>
20476 Computes the number of rows in which both inputs are non-null.
20482 <entry role=
"func_table_entry"><para role=
"func_signature">
20484 <primary>regression intercept
</primary>
20487 <primary>regr_intercept
</primary>
20489 <function>regr_intercept
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20490 <returnvalue>double precision
</returnvalue>
20493 Computes the y-intercept of the least-squares-fit linear equation
20495 (
<parameter>X
</parameter>,
<parameter>Y
</parameter>) pairs.
20501 <entry role=
"func_table_entry"><para role=
"func_signature">
20503 <primary>regr_r2
</primary>
20505 <function>regr_r2
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20506 <returnvalue>double precision
</returnvalue>
20509 Computes the square of the correlation coefficient.
20515 <entry role=
"func_table_entry"><para role=
"func_signature">
20517 <primary>regression slope
</primary>
20520 <primary>regr_slope
</primary>
20522 <function>regr_slope
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20523 <returnvalue>double precision
</returnvalue>
20526 Computes the slope of the least-squares-fit linear equation determined
20527 by the (
<parameter>X
</parameter>,
<parameter>Y
</parameter>)
20534 <entry role=
"func_table_entry"><para role=
"func_signature">
20536 <primary>regr_sxx
</primary>
20538 <function>regr_sxx
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20539 <returnvalue>double precision
</returnvalue>
20542 Computes the
<quote>sum of squares
</quote> of the independent
20544 <literal>sum(
<parameter>X
</parameter>^
2) - sum(
<parameter>X
</parameter>)^
2/
<parameter>N
</parameter></literal>.
20550 <entry role=
"func_table_entry"><para role=
"func_signature">
20552 <primary>regr_sxy
</primary>
20554 <function>regr_sxy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20555 <returnvalue>double precision
</returnvalue>
20558 Computes the
<quote>sum of products
</quote> of independent times
20559 dependent variables,
20560 <literal>sum(
<parameter>X
</parameter>*
<parameter>Y
</parameter>) - sum(
<parameter>X
</parameter>) * sum(
<parameter>Y
</parameter>)/
<parameter>N
</parameter></literal>.
20566 <entry role=
"func_table_entry"><para role=
"func_signature">
20568 <primary>regr_syy
</primary>
20570 <function>regr_syy
</function> (
<parameter>Y
</parameter> <type>double precision
</type>,
<parameter>X
</parameter> <type>double precision
</type> )
20571 <returnvalue>double precision
</returnvalue>
20574 Computes the
<quote>sum of squares
</quote> of the dependent
20576 <literal>sum(
<parameter>Y
</parameter>^
2) - sum(
<parameter>Y
</parameter>)^
2/
<parameter>N
</parameter></literal>.
20582 <entry role=
"func_table_entry"><para role=
"func_signature">
20584 <primary>standard deviation
</primary>
20587 <primary>stddev
</primary>
20589 <function>stddev
</function> (
<replaceable>numeric_type
</replaceable> )
20590 <returnvalue></returnvalue> <type>double precision
</type>
20591 for
<type>real
</type> or
<type>double precision
</type>,
20592 otherwise
<type>numeric
</type>
20595 This is a historical alias for
<function>stddev_samp
</function>.
20601 <entry role=
"func_table_entry"><para role=
"func_signature">
20603 <primary>standard deviation
</primary>
20604 <secondary>population
</secondary>
20607 <primary>stddev_pop
</primary>
20609 <function>stddev_pop
</function> (
<replaceable>numeric_type
</replaceable> )
20610 <returnvalue></returnvalue> <type>double precision
</type>
20611 for
<type>real
</type> or
<type>double precision
</type>,
20612 otherwise
<type>numeric
</type>
20615 Computes the population standard deviation of the input values.
20621 <entry role=
"func_table_entry"><para role=
"func_signature">
20623 <primary>standard deviation
</primary>
20624 <secondary>sample
</secondary>
20627 <primary>stddev_samp
</primary>
20629 <function>stddev_samp
</function> (
<replaceable>numeric_type
</replaceable> )
20630 <returnvalue></returnvalue> <type>double precision
</type>
20631 for
<type>real
</type> or
<type>double precision
</type>,
20632 otherwise
<type>numeric
</type>
20635 Computes the sample standard deviation of the input values.
20641 <entry role=
"func_table_entry"><para role=
"func_signature">
20643 <primary>variance
</primary>
20645 <function>variance
</function> (
<replaceable>numeric_type
</replaceable> )
20646 <returnvalue></returnvalue> <type>double precision
</type>
20647 for
<type>real
</type> or
<type>double precision
</type>,
20648 otherwise
<type>numeric
</type>
20651 This is a historical alias for
<function>var_samp
</function>.
20657 <entry role=
"func_table_entry"><para role=
"func_signature">
20659 <primary>variance
</primary>
20660 <secondary>population
</secondary>
20663 <primary>var_pop
</primary>
20665 <function>var_pop
</function> (
<replaceable>numeric_type
</replaceable> )
20666 <returnvalue></returnvalue> <type>double precision
</type>
20667 for
<type>real
</type> or
<type>double precision
</type>,
20668 otherwise
<type>numeric
</type>
20671 Computes the population variance of the input values (square of the
20672 population standard deviation).
20678 <entry role=
"func_table_entry"><para role=
"func_signature">
20680 <primary>variance
</primary>
20681 <secondary>sample
</secondary>
20684 <primary>var_samp
</primary>
20686 <function>var_samp
</function> (
<replaceable>numeric_type
</replaceable> )
20687 <returnvalue></returnvalue> <type>double precision
</type>
20688 for
<type>real
</type> or
<type>double precision
</type>,
20689 otherwise
<type>numeric
</type>
20692 Computes the sample variance of the input values (square of the sample
20693 standard deviation).
20702 <xref linkend=
"functions-orderedset-table"/> shows some
20703 aggregate functions that use the
<firstterm>ordered-set aggregate
</firstterm>
20704 syntax. These functions are sometimes referred to as
<quote>inverse
20705 distribution
</quote> functions. Their aggregated input is introduced by
20706 <literal>ORDER BY
</literal>, and they may also take a
<firstterm>direct
20707 argument
</firstterm> that is not aggregated, but is computed only once.
20708 All these functions ignore null values in their aggregated input.
20709 For those that take a
<parameter>fraction
</parameter> parameter, the
20710 fraction value must be between
0 and
1; an error is thrown if not.
20711 However, a null
<parameter>fraction
</parameter> value simply produces a
20716 <primary>ordered-set aggregate
</primary>
20717 <secondary>built-in
</secondary>
20720 <primary>inverse distribution
</primary>
20723 <table id=
"functions-orderedset-table">
20724 <title>Ordered-Set Aggregate Functions
</title>
20726 <colspec colname=
"col1" colwidth=
"10*"/>
20727 <colspec colname=
"col2" colwidth=
"1*"/>
20730 <entry role=
"func_table_entry"><para role=
"func_signature">
20736 <entry>Partial Mode
</entry>
20742 <entry role=
"func_table_entry"><para role=
"func_signature">
20744 <primary>mode
</primary>
20745 <secondary>statistical
</secondary>
20747 <function>mode
</function> ()
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
20748 <returnvalue>anyelement
</returnvalue>
20751 Computes the
<firstterm>mode
</firstterm>, the most frequent
20752 value of the aggregated argument (arbitrarily choosing the first one
20753 if there are multiple equally-frequent values). The aggregated
20754 argument must be of a sortable type.
20760 <entry role=
"func_table_entry"><para role=
"func_signature">
20762 <primary>percentile
</primary>
20763 <secondary>continuous
</secondary>
20765 <function>percentile_cont
</function> (
<parameter>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>double precision
</type> )
20766 <returnvalue>double precision
</returnvalue>
20768 <para role=
"func_signature">
20769 <function>percentile_cont
</function> (
<parameter>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>interval
</type> )
20770 <returnvalue>interval
</returnvalue>
20773 Computes the
<firstterm>continuous percentile
</firstterm>, a value
20774 corresponding to the specified
<parameter>fraction
</parameter>
20775 within the ordered set of aggregated argument values. This will
20776 interpolate between adjacent input items if needed.
20782 <entry role=
"func_table_entry"><para role=
"func_signature">
20783 <function>percentile_cont
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>double precision
</type> )
20784 <returnvalue>double precision[]
</returnvalue>
20786 <para role=
"func_signature">
20787 <function>percentile_cont
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>interval
</type> )
20788 <returnvalue>interval[]
</returnvalue>
20791 Computes multiple continuous percentiles. The result is an array of
20792 the same dimensions as the
<parameter>fractions
</parameter>
20793 parameter, with each non-null element replaced by the (possibly
20794 interpolated) value corresponding to that percentile.
20800 <entry role=
"func_table_entry"><para role=
"func_signature">
20802 <primary>percentile
</primary>
20803 <secondary>discrete
</secondary>
20805 <function>percentile_disc
</function> (
<parameter>fraction
</parameter> <type>double precision
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
20806 <returnvalue>anyelement
</returnvalue>
20809 Computes the
<firstterm>discrete percentile
</firstterm>, the first
20810 value within the ordered set of aggregated argument values whose
20811 position in the ordering equals or exceeds the
20812 specified
<parameter>fraction
</parameter>. The aggregated
20813 argument must be of a sortable type.
20819 <entry role=
"func_table_entry"><para role=
"func_signature">
20820 <function>percentile_disc
</function> (
<parameter>fractions
</parameter> <type>double precision[]
</type> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <type>anyelement
</type> )
20821 <returnvalue>anyarray
</returnvalue>
20824 Computes multiple discrete percentiles. The result is an array of the
20825 same dimensions as the
<parameter>fractions
</parameter> parameter,
20826 with each non-null element replaced by the input value corresponding
20827 to that percentile.
20828 The aggregated argument must be of a sortable type.
20837 <primary>hypothetical-set aggregate
</primary>
20838 <secondary>built-in
</secondary>
20842 Each of the
<quote>hypothetical-set
</quote> aggregates listed in
20843 <xref linkend=
"functions-hypothetical-table"/> is associated with a
20844 window function of the same name defined in
20845 <xref linkend=
"functions-window"/>. In each case, the aggregate's result
20846 is the value that the associated window function would have
20847 returned for the
<quote>hypothetical
</quote> row constructed from
20848 <replaceable>args
</replaceable>, if such a row had been added to the sorted
20849 group of rows represented by the
<replaceable>sorted_args
</replaceable>.
20850 For each of these functions, the list of direct arguments
20851 given in
<replaceable>args
</replaceable> must match the number and types of
20852 the aggregated arguments given in
<replaceable>sorted_args
</replaceable>.
20853 Unlike most built-in aggregates, these aggregates are not strict, that is
20854 they do not drop input rows containing nulls. Null values sort according
20855 to the rule specified in the
<literal>ORDER BY
</literal> clause.
20858 <table id=
"functions-hypothetical-table">
20859 <title>Hypothetical-Set Aggregate Functions
</title>
20861 <colspec colname=
"col1" colwidth=
"10*"/>
20862 <colspec colname=
"col2" colwidth=
"1*"/>
20865 <entry role=
"func_table_entry"><para role=
"func_signature">
20871 <entry>Partial Mode
</entry>
20877 <entry role=
"func_table_entry"><para role=
"func_signature">
20879 <primary>rank
</primary>
20880 <secondary>hypothetical
</secondary>
20882 <function>rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
20883 <returnvalue>bigint
</returnvalue>
20886 Computes the rank of the hypothetical row, with gaps; that is, the row
20887 number of the first row in its peer group.
20893 <entry role=
"func_table_entry"><para role=
"func_signature">
20895 <primary>dense_rank
</primary>
20896 <secondary>hypothetical
</secondary>
20898 <function>dense_rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
20899 <returnvalue>bigint
</returnvalue>
20902 Computes the rank of the hypothetical row, without gaps; this function
20903 effectively counts peer groups.
20909 <entry role=
"func_table_entry"><para role=
"func_signature">
20911 <primary>percent_rank
</primary>
20912 <secondary>hypothetical
</secondary>
20914 <function>percent_rank
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
20915 <returnvalue>double precision
</returnvalue>
20918 Computes the relative rank of the hypothetical row, that is
20919 (
<function>rank
</function> -
1) / (total rows -
1).
20920 The value thus ranges from
0 to
1 inclusive.
20926 <entry role=
"func_table_entry"><para role=
"func_signature">
20928 <primary>cume_dist
</primary>
20929 <secondary>hypothetical
</secondary>
20931 <function>cume_dist
</function> (
<replaceable>args
</replaceable> )
<literal>WITHIN GROUP
</literal> (
<literal>ORDER BY
</literal> <replaceable>sorted_args
</replaceable> )
20932 <returnvalue>double precision
</returnvalue>
20935 Computes the cumulative distribution, that is (number of rows
20936 preceding or peers with hypothetical row) / (total rows). The value
20937 thus ranges from
1/
<parameter>N
</parameter> to
1.
20945 <table id=
"functions-grouping-table">
20946 <title>Grouping Operations
</title>
20950 <entry role=
"func_table_entry"><para role=
"func_signature">
20961 <entry role=
"func_table_entry"><para role=
"func_signature">
20963 <primary>GROUPING
</primary>
20965 <function>GROUPING
</function> (
<replaceable>group_by_expression(s)
</replaceable> )
20966 <returnvalue>integer
</returnvalue>
20969 Returns a bit mask indicating which
<literal>GROUP BY
</literal>
20970 expressions are not included in the current grouping set.
20971 Bits are assigned with the rightmost argument corresponding to the
20972 least-significant bit; each bit is
0 if the corresponding expression
20973 is included in the grouping criteria of the grouping set generating
20974 the current result row, and
1 if it is not included.
20982 The grouping operations shown in
20983 <xref linkend=
"functions-grouping-table"/> are used in conjunction with
20984 grouping sets (see
<xref linkend=
"queries-grouping-sets"/>) to distinguish
20985 result rows. The arguments to the
<literal>GROUPING
</literal> function
20986 are not actually evaluated, but they must exactly match expressions given
20987 in the
<literal>GROUP BY
</literal> clause of the associated query level.
20990 <prompt>=
></prompt> <userinput>SELECT * FROM items_sold;
</userinput>
20991 make | model | sales
20992 -------+-------+-------
20999 <prompt>=
></prompt> <userinput>SELECT make, model, GROUPING(make,model), sum(sales) FROM items_sold GROUP BY ROLLUP(make,model);
</userinput>
21000 make | model | grouping | sum
21001 -------+-------+----------+-----
21003 Foo | Tour |
0 |
20
21004 Bar | City |
0 |
15
21005 Bar | Sport |
0 |
5
21011 Here, the
<literal>grouping
</literal> value
<literal>0</literal> in the
21012 first four rows shows that those have been grouped normally, over both the
21013 grouping columns. The value
<literal>1</literal> indicates
21014 that
<literal>model
</literal> was not grouped by in the next-to-last two
21015 rows, and the value
<literal>3</literal> indicates that
21016 neither
<literal>make
</literal> nor
<literal>model
</literal> was grouped
21017 by in the last row (which therefore is an aggregate over all the input
21023 <sect1 id=
"functions-window">
21024 <title>Window Functions
</title>
21026 <indexterm zone=
"functions-window">
21027 <primary>window function
</primary>
21028 <secondary>built-in
</secondary>
21032 <firstterm>Window functions
</firstterm> provide the ability to perform
21033 calculations across sets of rows that are related to the current query
21034 row. See
<xref linkend=
"tutorial-window"/> for an introduction to this
21035 feature, and
<xref linkend=
"syntax-window-functions"/> for syntax
21040 The built-in window functions are listed in
21041 <xref linkend=
"functions-window-table"/>. Note that these functions
21042 <emphasis>must
</emphasis> be invoked using window function syntax, i.e., an
21043 <literal>OVER
</literal> clause is required.
21047 In addition to these functions, any built-in or user-defined
21048 ordinary aggregate (i.e., not ordered-set or hypothetical-set aggregates)
21049 can be used as a window function; see
21050 <xref linkend=
"functions-aggregate"/> for a list of the built-in aggregates.
21051 Aggregate functions act as window functions only when an
<literal>OVER
</literal>
21052 clause follows the call; otherwise they act as plain aggregates
21053 and return a single row for the entire set.
21056 <table id=
"functions-window-table">
21057 <title>General-Purpose Window Functions
</title>
21061 <entry role=
"func_table_entry"><para role=
"func_signature">
21072 <entry role=
"func_table_entry"><para role=
"func_signature">
21074 <primary>row_number
</primary>
21076 <function>row_number
</function> ()
21077 <returnvalue>bigint
</returnvalue>
21080 Returns the number of the current row within its partition, counting
21086 <entry role=
"func_table_entry"><para role=
"func_signature">
21088 <primary>rank
</primary>
21090 <function>rank
</function> ()
21091 <returnvalue>bigint
</returnvalue>
21094 Returns the rank of the current row, with gaps; that is,
21095 the
<function>row_number
</function> of the first row in its peer
21101 <entry role=
"func_table_entry"><para role=
"func_signature">
21103 <primary>dense_rank
</primary>
21105 <function>dense_rank
</function> ()
21106 <returnvalue>bigint
</returnvalue>
21109 Returns the rank of the current row, without gaps; this function
21110 effectively counts peer groups.
21115 <entry role=
"func_table_entry"><para role=
"func_signature">
21117 <primary>percent_rank
</primary>
21119 <function>percent_rank
</function> ()
21120 <returnvalue>double precision
</returnvalue>
21123 Returns the relative rank of the current row, that is
21124 (
<function>rank
</function> -
1) / (total partition rows -
1).
21125 The value thus ranges from
0 to
1 inclusive.
21130 <entry role=
"func_table_entry"><para role=
"func_signature">
21132 <primary>cume_dist
</primary>
21134 <function>cume_dist
</function> ()
21135 <returnvalue>double precision
</returnvalue>
21138 Returns the cumulative distribution, that is (number of partition rows
21139 preceding or peers with current row) / (total partition rows).
21140 The value thus ranges from
1/
<parameter>N
</parameter> to
1.
21145 <entry role=
"func_table_entry"><para role=
"func_signature">
21147 <primary>ntile
</primary>
21149 <function>ntile
</function> (
<parameter>num_buckets
</parameter> <type>integer
</type> )
21150 <returnvalue>integer
</returnvalue>
21153 Returns an integer ranging from
1 to the argument value, dividing the
21154 partition as equally as possible.
21159 <entry role=
"func_table_entry"><para role=
"func_signature">
21161 <primary>lag
</primary>
21163 <function>lag
</function> (
<parameter>value
</parameter> <type>anycompatible
</type>
21164 <optional>,
<parameter>offset
</parameter> <type>integer
</type>
21165 <optional>,
<parameter>default
</parameter> <type>anycompatible
</type> </optional></optional> )
21166 <returnvalue>anycompatible
</returnvalue>
21169 Returns
<parameter>value
</parameter> evaluated at
21170 the row that is
<parameter>offset
</parameter>
21171 rows before the current row within the partition; if there is no such
21172 row, instead returns
<parameter>default
</parameter>
21173 (which must be of a type compatible with
21174 <parameter>value
</parameter>).
21175 Both
<parameter>offset
</parameter> and
21176 <parameter>default
</parameter> are evaluated
21177 with respect to the current row. If omitted,
21178 <parameter>offset
</parameter> defaults to
1 and
21179 <parameter>default
</parameter> to
<literal>NULL
</literal>.
21184 <entry role=
"func_table_entry"><para role=
"func_signature">
21186 <primary>lead
</primary>
21188 <function>lead
</function> (
<parameter>value
</parameter> <type>anycompatible
</type>
21189 <optional>,
<parameter>offset
</parameter> <type>integer
</type>
21190 <optional>,
<parameter>default
</parameter> <type>anycompatible
</type> </optional></optional> )
21191 <returnvalue>anycompatible
</returnvalue>
21194 Returns
<parameter>value
</parameter> evaluated at
21195 the row that is
<parameter>offset
</parameter>
21196 rows after the current row within the partition; if there is no such
21197 row, instead returns
<parameter>default
</parameter>
21198 (which must be of a type compatible with
21199 <parameter>value
</parameter>).
21200 Both
<parameter>offset
</parameter> and
21201 <parameter>default
</parameter> are evaluated
21202 with respect to the current row. If omitted,
21203 <parameter>offset
</parameter> defaults to
1 and
21204 <parameter>default
</parameter> to
<literal>NULL
</literal>.
21209 <entry role=
"func_table_entry"><para role=
"func_signature">
21211 <primary>first_value
</primary>
21213 <function>first_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type> )
21214 <returnvalue>anyelement
</returnvalue>
21217 Returns
<parameter>value
</parameter> evaluated
21218 at the row that is the first row of the window frame.
21223 <entry role=
"func_table_entry"><para role=
"func_signature">
21225 <primary>last_value
</primary>
21227 <function>last_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type> )
21228 <returnvalue>anyelement
</returnvalue>
21231 Returns
<parameter>value
</parameter> evaluated
21232 at the row that is the last row of the window frame.
21237 <entry role=
"func_table_entry"><para role=
"func_signature">
21239 <primary>nth_value
</primary>
21241 <function>nth_value
</function> (
<parameter>value
</parameter> <type>anyelement
</type>,
<parameter>n
</parameter> <type>integer
</type> )
21242 <returnvalue>anyelement
</returnvalue>
21245 Returns
<parameter>value
</parameter> evaluated
21246 at the row that is the
<parameter>n
</parameter>'th
21247 row of the window frame (counting from
1);
21248 returns
<literal>NULL
</literal> if there is no such row.
21256 All of the functions listed in
21257 <xref linkend=
"functions-window-table"/> depend on the sort ordering
21258 specified by the
<literal>ORDER BY
</literal> clause of the associated window
21259 definition. Rows that are not distinct when considering only the
21260 <literal>ORDER BY
</literal> columns are said to be
<firstterm>peers
</firstterm>.
21261 The four ranking functions (including
<function>cume_dist
</function>) are
21262 defined so that they give the same answer for all rows of a peer group.
21266 Note that
<function>first_value
</function>,
<function>last_value
</function>, and
21267 <function>nth_value
</function> consider only the rows within the
<quote>window
21268 frame
</quote>, which by default contains the rows from the start of the
21269 partition through the last peer of the current row. This is
21270 likely to give unhelpful results for
<function>last_value
</function> and
21271 sometimes also
<function>nth_value
</function>. You can redefine the frame by
21272 adding a suitable frame specification (
<literal>RANGE
</literal>,
21273 <literal>ROWS
</literal> or
<literal>GROUPS
</literal>) to
21274 the
<literal>OVER
</literal> clause.
21275 See
<xref linkend=
"syntax-window-functions"/> for more information
21276 about frame specifications.
21280 When an aggregate function is used as a window function, it aggregates
21281 over the rows within the current row's window frame.
21282 An aggregate used with
<literal>ORDER BY
</literal> and the default window frame
21283 definition produces a
<quote>running sum
</quote> type of behavior, which may or
21284 may not be what's wanted. To obtain
21285 aggregation over the whole partition, omit
<literal>ORDER BY
</literal> or use
21286 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING
</literal>.
21287 Other frame specifications can be used to obtain other effects.
21292 The SQL standard defines a
<literal>RESPECT NULLS
</literal> or
21293 <literal>IGNORE NULLS
</literal> option for
<function>lead
</function>,
<function>lag
</function>,
21294 <function>first_value
</function>,
<function>last_value
</function>, and
21295 <function>nth_value
</function>. This is not implemented in
21296 <productname>PostgreSQL
</productname>: the behavior is always the
21297 same as the standard's default, namely
<literal>RESPECT NULLS
</literal>.
21298 Likewise, the standard's
<literal>FROM FIRST
</literal> or
<literal>FROM LAST
</literal>
21299 option for
<function>nth_value
</function> is not implemented: only the
21300 default
<literal>FROM FIRST
</literal> behavior is supported. (You can achieve
21301 the result of
<literal>FROM LAST
</literal> by reversing the
<literal>ORDER BY
</literal>
21308 <sect1 id=
"functions-subquery">
21309 <title>Subquery Expressions
</title>
21312 <primary>EXISTS
</primary>
21316 <primary>IN
</primary>
21320 <primary>NOT IN
</primary>
21324 <primary>ANY
</primary>
21328 <primary>ALL
</primary>
21332 <primary>SOME
</primary>
21336 <primary>subquery
</primary>
21340 This section describes the
<acronym>SQL
</acronym>-compliant subquery
21341 expressions available in
<productname>PostgreSQL
</productname>.
21342 All of the expression forms documented in this section return
21343 Boolean (true/false) results.
21346 <sect2 id=
"functions-subquery-exists">
21347 <title><literal>EXISTS
</literal></title>
21350 EXISTS (
<replaceable>subquery
</replaceable>)
21354 The argument of
<token>EXISTS
</token> is an arbitrary
<command>SELECT
</command> statement,
21355 or
<firstterm>subquery
</firstterm>. The
21356 subquery is evaluated to determine whether it returns any rows.
21357 If it returns at least one row, the result of
<token>EXISTS
</token> is
21358 <quote>true
</quote>; if the subquery returns no rows, the result of
<token>EXISTS
</token>
21359 is
<quote>false
</quote>.
21363 The subquery can refer to variables from the surrounding query,
21364 which will act as constants during any one evaluation of the subquery.
21368 The subquery will generally only be executed long enough to determine
21369 whether at least one row is returned, not all the way to completion.
21370 It is unwise to write a subquery that has side effects (such as
21371 calling sequence functions); whether the side effects occur
21372 might be unpredictable.
21376 Since the result depends only on whether any rows are returned,
21377 and not on the contents of those rows, the output list of the
21378 subquery is normally unimportant. A common coding convention is
21379 to write all
<literal>EXISTS
</literal> tests in the form
21380 <literal>EXISTS(SELECT
1 WHERE ...)
</literal>. There are exceptions to
21381 this rule however, such as subqueries that use
<token>INTERSECT
</token>.
21385 This simple example is like an inner join on
<literal>col2
</literal>, but
21386 it produces at most one output row for each
<literal>tab1
</literal> row,
21387 even if there are several matching
<literal>tab2
</literal> rows:
21391 WHERE EXISTS (SELECT
1 FROM tab2 WHERE col2 = tab1.col2);
21396 <sect2 id=
"functions-subquery-in">
21397 <title><literal>IN
</literal></title>
21400 <replaceable>expression
</replaceable> IN (
<replaceable>subquery
</replaceable>)
21404 The right-hand side is a parenthesized
21405 subquery, which must return exactly one column. The left-hand expression
21406 is evaluated and compared to each row of the subquery result.
21407 The result of
<token>IN
</token> is
<quote>true
</quote> if any equal subquery row is found.
21408 The result is
<quote>false
</quote> if no equal row is found (including the
21409 case where the subquery returns no rows).
21413 Note that if the left-hand expression yields null, or if there are
21414 no equal right-hand values and at least one right-hand row yields
21415 null, the result of the
<token>IN
</token> construct will be null, not false.
21416 This is in accordance with SQL's normal rules for Boolean combinations
21421 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
21422 be evaluated completely.
21426 <replaceable>row_constructor
</replaceable> IN (
<replaceable>subquery
</replaceable>)
21430 The left-hand side of this form of
<token>IN
</token> is a row constructor,
21431 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
21432 The right-hand side is a parenthesized
21433 subquery, which must return exactly as many columns as there are
21434 expressions in the left-hand row. The left-hand expressions are
21435 evaluated and compared row-wise to each row of the subquery result.
21436 The result of
<token>IN
</token> is
<quote>true
</quote> if any equal subquery row is found.
21437 The result is
<quote>false
</quote> if no equal row is found (including the
21438 case where the subquery returns no rows).
21442 As usual, null values in the rows are combined per
21443 the normal rules of SQL Boolean expressions. Two rows are considered
21444 equal if all their corresponding members are non-null and equal; the rows
21445 are unequal if any corresponding members are non-null and unequal;
21446 otherwise the result of that row comparison is unknown (null).
21447 If all the per-row results are either unequal or null, with at least one
21448 null, then the result of
<token>IN
</token> is null.
21452 <sect2 id=
"functions-subquery-notin">
21453 <title><literal>NOT IN
</literal></title>
21456 <replaceable>expression
</replaceable> NOT IN (
<replaceable>subquery
</replaceable>)
21460 The right-hand side is a parenthesized
21461 subquery, which must return exactly one column. The left-hand expression
21462 is evaluated and compared to each row of the subquery result.
21463 The result of
<token>NOT IN
</token> is
<quote>true
</quote> if only unequal subquery rows
21464 are found (including the case where the subquery returns no rows).
21465 The result is
<quote>false
</quote> if any equal row is found.
21469 Note that if the left-hand expression yields null, or if there are
21470 no equal right-hand values and at least one right-hand row yields
21471 null, the result of the
<token>NOT IN
</token> construct will be null, not true.
21472 This is in accordance with SQL's normal rules for Boolean combinations
21477 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
21478 be evaluated completely.
21482 <replaceable>row_constructor
</replaceable> NOT IN (
<replaceable>subquery
</replaceable>)
21486 The left-hand side of this form of
<token>NOT IN
</token> is a row constructor,
21487 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
21488 The right-hand side is a parenthesized
21489 subquery, which must return exactly as many columns as there are
21490 expressions in the left-hand row. The left-hand expressions are
21491 evaluated and compared row-wise to each row of the subquery result.
21492 The result of
<token>NOT IN
</token> is
<quote>true
</quote> if only unequal subquery rows
21493 are found (including the case where the subquery returns no rows).
21494 The result is
<quote>false
</quote> if any equal row is found.
21498 As usual, null values in the rows are combined per
21499 the normal rules of SQL Boolean expressions. Two rows are considered
21500 equal if all their corresponding members are non-null and equal; the rows
21501 are unequal if any corresponding members are non-null and unequal;
21502 otherwise the result of that row comparison is unknown (null).
21503 If all the per-row results are either unequal or null, with at least one
21504 null, then the result of
<token>NOT IN
</token> is null.
21508 <sect2 id=
"functions-subquery-any-some">
21509 <title><literal>ANY
</literal>/
<literal>SOME
</literal></title>
21512 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>subquery
</replaceable>)
21513 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>subquery
</replaceable>)
21517 The right-hand side is a parenthesized
21518 subquery, which must return exactly one column. The left-hand expression
21519 is evaluated and compared to each row of the subquery result using the
21520 given
<replaceable>operator
</replaceable>, which must yield a Boolean
21522 The result of
<token>ANY
</token> is
<quote>true
</quote> if any true result is obtained.
21523 The result is
<quote>false
</quote> if no true result is found (including the
21524 case where the subquery returns no rows).
21528 <token>SOME
</token> is a synonym for
<token>ANY
</token>.
21529 <token>IN
</token> is equivalent to
<literal>= ANY
</literal>.
21533 Note that if there are no successes and at least one right-hand row yields
21534 null for the operator's result, the result of the
<token>ANY
</token> construct
21535 will be null, not false.
21536 This is in accordance with SQL's normal rules for Boolean combinations
21541 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
21542 be evaluated completely.
21546 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>subquery
</replaceable>)
21547 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>subquery
</replaceable>)
21551 The left-hand side of this form of
<token>ANY
</token> is a row constructor,
21552 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
21553 The right-hand side is a parenthesized
21554 subquery, which must return exactly as many columns as there are
21555 expressions in the left-hand row. The left-hand expressions are
21556 evaluated and compared row-wise to each row of the subquery result,
21557 using the given
<replaceable>operator
</replaceable>.
21558 The result of
<token>ANY
</token> is
<quote>true
</quote> if the comparison
21559 returns true for any subquery row.
21560 The result is
<quote>false
</quote> if the comparison returns false for every
21561 subquery row (including the case where the subquery returns no
21563 The result is NULL if no comparison with a subquery row returns true,
21564 and at least one comparison returns NULL.
21568 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
21569 of a row constructor comparison.
21573 <sect2 id=
"functions-subquery-all">
21574 <title><literal>ALL
</literal></title>
21577 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>subquery
</replaceable>)
21581 The right-hand side is a parenthesized
21582 subquery, which must return exactly one column. The left-hand expression
21583 is evaluated and compared to each row of the subquery result using the
21584 given
<replaceable>operator
</replaceable>, which must yield a Boolean
21586 The result of
<token>ALL
</token> is
<quote>true
</quote> if all rows yield true
21587 (including the case where the subquery returns no rows).
21588 The result is
<quote>false
</quote> if any false result is found.
21589 The result is NULL if no comparison with a subquery row returns false,
21590 and at least one comparison returns NULL.
21594 <token>NOT IN
</token> is equivalent to
<literal><> ALL
</literal>.
21598 As with
<token>EXISTS
</token>, it's unwise to assume that the subquery will
21599 be evaluated completely.
21603 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>subquery
</replaceable>)
21607 The left-hand side of this form of
<token>ALL
</token> is a row constructor,
21608 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
21609 The right-hand side is a parenthesized
21610 subquery, which must return exactly as many columns as there are
21611 expressions in the left-hand row. The left-hand expressions are
21612 evaluated and compared row-wise to each row of the subquery result,
21613 using the given
<replaceable>operator
</replaceable>.
21614 The result of
<token>ALL
</token> is
<quote>true
</quote> if the comparison
21615 returns true for all subquery rows (including the
21616 case where the subquery returns no rows).
21617 The result is
<quote>false
</quote> if the comparison returns false for any
21619 The result is NULL if no comparison with a subquery row returns false,
21620 and at least one comparison returns NULL.
21624 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
21625 of a row constructor comparison.
21629 <sect2 id=
"functions-subquery-single-row-comp">
21630 <title>Single-Row Comparison
</title>
21632 <indexterm zone=
"functions-subquery">
21633 <primary>comparison
</primary>
21634 <secondary>subquery result row
</secondary>
21638 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> (
<replaceable>subquery
</replaceable>)
21642 The left-hand side is a row constructor,
21643 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
21644 The right-hand side is a parenthesized subquery, which must return exactly
21645 as many columns as there are expressions in the left-hand row. Furthermore,
21646 the subquery cannot return more than one row. (If it returns zero rows,
21647 the result is taken to be null.) The left-hand side is evaluated and
21648 compared row-wise to the single subquery result row.
21652 See
<xref linkend=
"row-wise-comparison"/> for details about the meaning
21653 of a row constructor comparison.
21659 <sect1 id=
"functions-comparisons">
21660 <title>Row and Array Comparisons
</title>
21663 <primary>IN
</primary>
21667 <primary>NOT IN
</primary>
21671 <primary>ANY
</primary>
21675 <primary>ALL
</primary>
21679 <primary>SOME
</primary>
21683 <primary>composite type
</primary>
21684 <secondary>comparison
</secondary>
21688 <primary>row-wise comparison
</primary>
21692 <primary>comparison
</primary>
21693 <secondary>composite type
</secondary>
21697 <primary>comparison
</primary>
21698 <secondary>row constructor
</secondary>
21702 <primary>IS DISTINCT FROM
</primary>
21706 <primary>IS NOT DISTINCT FROM
</primary>
21710 This section describes several specialized constructs for making
21711 multiple comparisons between groups of values. These forms are
21712 syntactically related to the subquery forms of the previous section,
21713 but do not involve subqueries.
21714 The forms involving array subexpressions are
21715 <productname>PostgreSQL
</productname> extensions; the rest are
21716 <acronym>SQL
</acronym>-compliant.
21717 All of the expression forms documented in this section return
21718 Boolean (true/false) results.
21721 <sect2 id=
"functions-comparisons-in-scalar">
21722 <title><literal>IN
</literal></title>
21725 <replaceable>expression
</replaceable> IN (
<replaceable>value
</replaceable> <optional>, ...
</optional>)
21729 The right-hand side is a parenthesized list
21730 of scalar expressions. The result is
<quote>true
</quote> if the left-hand expression's
21731 result is equal to any of the right-hand expressions. This is a shorthand
21735 <replaceable>expression
</replaceable> =
<replaceable>value1
</replaceable>
21737 <replaceable>expression
</replaceable> =
<replaceable>value2
</replaceable>
21744 Note that if the left-hand expression yields null, or if there are
21745 no equal right-hand values and at least one right-hand expression yields
21746 null, the result of the
<token>IN
</token> construct will be null, not false.
21747 This is in accordance with SQL's normal rules for Boolean combinations
21752 <sect2 id=
"functions-comparisons-not-in">
21753 <title><literal>NOT IN
</literal></title>
21756 <replaceable>expression
</replaceable> NOT IN (
<replaceable>value
</replaceable> <optional>, ...
</optional>)
21760 The right-hand side is a parenthesized list
21761 of scalar expressions. The result is
<quote>true
</quote> if the left-hand expression's
21762 result is unequal to all of the right-hand expressions. This is a shorthand
21766 <replaceable>expression
</replaceable> <> <replaceable>value1
</replaceable>
21768 <replaceable>expression
</replaceable> <> <replaceable>value2
</replaceable>
21775 Note that if the left-hand expression yields null, or if there are
21776 no equal right-hand values and at least one right-hand expression yields
21777 null, the result of the
<token>NOT IN
</token> construct will be null, not true
21778 as one might naively expect.
21779 This is in accordance with SQL's normal rules for Boolean combinations
21785 <literal>x NOT IN y
</literal> is equivalent to
<literal>NOT (x IN y)
</literal> in all
21786 cases. However, null values are much more likely to trip up the novice when
21787 working with
<token>NOT IN
</token> than when working with
<token>IN
</token>.
21788 It is best to express your condition positively if possible.
21793 <sect2 id=
"functions-comparisons-any-some">
21794 <title><literal>ANY
</literal>/
<literal>SOME
</literal> (array)
</title>
21797 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ANY (
<replaceable>array expression
</replaceable>)
21798 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> SOME (
<replaceable>array expression
</replaceable>)
21802 The right-hand side is a parenthesized expression, which must yield an
21804 The left-hand expression
21805 is evaluated and compared to each element of the array using the
21806 given
<replaceable>operator
</replaceable>, which must yield a Boolean
21808 The result of
<token>ANY
</token> is
<quote>true
</quote> if any true result is obtained.
21809 The result is
<quote>false
</quote> if no true result is found (including the
21810 case where the array has zero elements).
21814 If the array expression yields a null array, the result of
21815 <token>ANY
</token> will be null. If the left-hand expression yields null,
21816 the result of
<token>ANY
</token> is ordinarily null (though a non-strict
21817 comparison operator could possibly yield a different result).
21818 Also, if the right-hand array contains any null elements and no true
21819 comparison result is obtained, the result of
<token>ANY
</token>
21820 will be null, not false (again, assuming a strict comparison operator).
21821 This is in accordance with SQL's normal rules for Boolean combinations
21826 <token>SOME
</token> is a synonym for
<token>ANY
</token>.
21830 <sect2 id=
"functions-comparisons-all">
21831 <title><literal>ALL
</literal> (array)
</title>
21834 <replaceable>expression
</replaceable> <replaceable>operator
</replaceable> ALL (
<replaceable>array expression
</replaceable>)
21838 The right-hand side is a parenthesized expression, which must yield an
21840 The left-hand expression
21841 is evaluated and compared to each element of the array using the
21842 given
<replaceable>operator
</replaceable>, which must yield a Boolean
21844 The result of
<token>ALL
</token> is
<quote>true
</quote> if all comparisons yield true
21845 (including the case where the array has zero elements).
21846 The result is
<quote>false
</quote> if any false result is found.
21850 If the array expression yields a null array, the result of
21851 <token>ALL
</token> will be null. If the left-hand expression yields null,
21852 the result of
<token>ALL
</token> is ordinarily null (though a non-strict
21853 comparison operator could possibly yield a different result).
21854 Also, if the right-hand array contains any null elements and no false
21855 comparison result is obtained, the result of
<token>ALL
</token>
21856 will be null, not true (again, assuming a strict comparison operator).
21857 This is in accordance with SQL's normal rules for Boolean combinations
21862 <sect2 id=
"row-wise-comparison">
21863 <title>Row Constructor Comparison
</title>
21866 <replaceable>row_constructor
</replaceable> <replaceable>operator
</replaceable> <replaceable>row_constructor
</replaceable>
21870 Each side is a row constructor,
21871 as described in
<xref linkend=
"sql-syntax-row-constructors"/>.
21872 The two row values must have the same number of fields.
21873 Each side is evaluated and they are compared row-wise. Row constructor
21874 comparisons are allowed when the
<replaceable>operator
</replaceable> is
21875 <literal>=
</literal>,
21876 <literal><></literal>,
21877 <literal><</literal>,
21878 <literal><=
</literal>,
21879 <literal>></literal> or
21880 <literal>>=
</literal>.
21881 Every row element must be of a type which has a default B-tree operator
21882 class or the attempted comparison may generate an error.
21887 Errors related to the number or types of elements might not occur if
21888 the comparison is resolved using earlier columns.
21893 The
<literal>=
</literal> and
<literal><></literal> cases work slightly differently
21894 from the others. Two rows are considered
21895 equal if all their corresponding members are non-null and equal; the rows
21896 are unequal if any corresponding members are non-null and unequal;
21897 otherwise the result of the row comparison is unknown (null).
21901 For the
<literal><</literal>,
<literal><=
</literal>,
<literal>></literal> and
21902 <literal>>=
</literal> cases, the row elements are compared left-to-right,
21903 stopping as soon as an unequal or null pair of elements is found.
21904 If either of this pair of elements is null, the result of the
21905 row comparison is unknown (null); otherwise comparison of this pair
21906 of elements determines the result. For example,
21907 <literal>ROW(
1,
2,NULL)
< ROW(
1,
3,
0)
</literal>
21908 yields true, not null, because the third pair of elements are not
21914 Prior to
<productname>PostgreSQL
</productname> 8.2, the
21915 <literal><</literal>,
<literal><=
</literal>,
<literal>></literal> and
<literal>>=
</literal>
21916 cases were not handled per SQL specification. A comparison like
21917 <literal>ROW(a,b)
< ROW(c,d)
</literal>
21919 <literal>a
< c AND b
< d
</literal>
21920 whereas the correct behavior is equivalent to
21921 <literal>a
< c OR (a = c AND b
< d)
</literal>.
21926 <replaceable>row_constructor
</replaceable> IS DISTINCT FROM
<replaceable>row_constructor
</replaceable>
21930 This construct is similar to a
<literal><></literal> row comparison,
21931 but it does not yield null for null inputs. Instead, any null value is
21932 considered unequal to (distinct from) any non-null value, and any two
21933 nulls are considered equal (not distinct). Thus the result will
21934 either be true or false, never null.
21938 <replaceable>row_constructor
</replaceable> IS NOT DISTINCT FROM
<replaceable>row_constructor
</replaceable>
21942 This construct is similar to a
<literal>=
</literal> row comparison,
21943 but it does not yield null for null inputs. Instead, any null value is
21944 considered unequal to (distinct from) any non-null value, and any two
21945 nulls are considered equal (not distinct). Thus the result will always
21946 be either true or false, never null.
21951 <sect2 id=
"composite-type-comparison">
21952 <title>Composite Type Comparison
</title>
21955 <replaceable>record
</replaceable> <replaceable>operator
</replaceable> <replaceable>record
</replaceable>
21959 The SQL specification requires row-wise comparison to return NULL if the
21960 result depends on comparing two NULL values or a NULL and a non-NULL.
21961 <productname>PostgreSQL
</productname> does this only when comparing the
21962 results of two row constructors (as in
21963 <xref linkend=
"row-wise-comparison"/>) or comparing a row constructor
21964 to the output of a subquery (as in
<xref linkend=
"functions-subquery"/>).
21965 In other contexts where two composite-type values are compared, two
21966 NULL field values are considered equal, and a NULL is considered larger
21967 than a non-NULL. This is necessary in order to have consistent sorting
21968 and indexing behavior for composite types.
21972 Each side is evaluated and they are compared row-wise. Composite type
21973 comparisons are allowed when the
<replaceable>operator
</replaceable> is
21974 <literal>=
</literal>,
21975 <literal><></literal>,
21976 <literal><</literal>,
21977 <literal><=
</literal>,
21978 <literal>></literal> or
21979 <literal>>=
</literal>,
21980 or has semantics similar to one of these. (To be specific, an operator
21981 can be a row comparison operator if it is a member of a B-tree operator
21982 class, or is the negator of the
<literal>=
</literal> member of a B-tree operator
21983 class.) The default behavior of the above operators is the same as for
21984 <literal>IS [ NOT ] DISTINCT FROM
</literal> for row constructors (see
21985 <xref linkend=
"row-wise-comparison"/>).
21989 To support matching of rows which include elements without a default
21990 B-tree operator class, the following operators are defined for composite
21992 <literal>*=
</literal>,
21993 <literal>*
<></literal>,
21994 <literal>*
<</literal>,
21995 <literal>*
<=
</literal>,
21996 <literal>*
></literal>, and
21997 <literal>*
>=
</literal>.
21998 These operators compare the internal binary representation of the two
21999 rows. Two rows might have a different binary representation even
22000 though comparisons of the two rows with the equality operator is true.
22001 The ordering of rows under these comparison operators is deterministic
22002 but not otherwise meaningful. These operators are used internally
22003 for materialized views and might be useful for other specialized
22004 purposes such as replication and B-Tree deduplication (see
<xref
22005 linkend=
"btree-deduplication"/>). They are not intended to be
22006 generally useful for writing queries, though.
22011 <sect1 id=
"functions-srf">
22012 <title>Set Returning Functions
</title>
22014 <indexterm zone=
"functions-srf">
22015 <primary>set returning functions
</primary>
22016 <secondary>functions
</secondary>
22020 This section describes functions that possibly return more than one row.
22021 The most widely used functions in this class are series generating
22022 functions, as detailed in
<xref linkend=
"functions-srf-series"/> and
22023 <xref linkend=
"functions-srf-subscripts"/>. Other, more specialized
22024 set-returning functions are described elsewhere in this manual.
22025 See
<xref linkend=
"queries-tablefunctions"/> for ways to combine multiple
22026 set-returning functions.
22029 <table id=
"functions-srf-series">
22030 <title>Series Generating Functions
</title>
22034 <entry role=
"func_table_entry"><para role=
"func_signature">
22045 <entry role=
"func_table_entry"><para role=
"func_signature">
22047 <primary>generate_series
</primary>
22049 <function>generate_series
</function> (
<parameter>start
</parameter> <type>integer
</type>,
<parameter>stop
</parameter> <type>integer
</type> <optional>,
<parameter>step
</parameter> <type>integer
</type> </optional> )
22050 <returnvalue>setof integer
</returnvalue>
22052 <para role=
"func_signature">
22053 <function>generate_series
</function> (
<parameter>start
</parameter> <type>bigint
</type>,
<parameter>stop
</parameter> <type>bigint
</type> <optional>,
<parameter>step
</parameter> <type>bigint
</type> </optional> )
22054 <returnvalue>setof bigint
</returnvalue>
22056 <para role=
"func_signature">
22057 <function>generate_series
</function> (
<parameter>start
</parameter> <type>numeric
</type>,
<parameter>stop
</parameter> <type>numeric
</type> <optional>,
<parameter>step
</parameter> <type>numeric
</type> </optional> )
22058 <returnvalue>setof numeric
</returnvalue>
22061 Generates a series of values from
<parameter>start
</parameter>
22062 to
<parameter>stop
</parameter>, with a step size
22063 of
<parameter>step
</parameter>.
<parameter>step
</parameter>
22069 <entry role=
"func_table_entry"><para role=
"func_signature">
22070 <function>generate_series
</function> (
<parameter>start
</parameter> <type>timestamp
</type>,
<parameter>stop
</parameter> <type>timestamp
</type>,
<parameter>step
</parameter> <type>interval
</type> )
22071 <returnvalue>setof timestamp
</returnvalue>
22073 <para role=
"func_signature">
22074 <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> )
22075 <returnvalue>setof timestamp with time zone
</returnvalue>
22078 Generates a series of values from
<parameter>start
</parameter>
22079 to
<parameter>stop
</parameter>, with a step size
22080 of
<parameter>step
</parameter>.
22081 In the timezone-aware form, times of day and daylight-savings
22082 adjustments are computed according to the time zone named by
22083 the
<parameter>timezone
</parameter> argument, or the current
22084 <xref linkend=
"guc-timezone"/> setting if that is omitted.
22092 When
<parameter>step
</parameter> is positive, zero rows are returned if
22093 <parameter>start
</parameter> is greater than
<parameter>stop
</parameter>.
22094 Conversely, when
<parameter>step
</parameter> is negative, zero rows are
22095 returned if
<parameter>start
</parameter> is less than
<parameter>stop
</parameter>.
22096 Zero rows are also returned if any input is
<literal>NULL
</literal>.
22098 for
<parameter>step
</parameter> to be zero. Some examples follow:
22100 SELECT * FROM generate_series(
2,
4);
22108 SELECT * FROM generate_series(
5,
1,-
2);
22116 SELECT * FROM generate_series(
4,
3);
22121 SELECT generate_series(
1.1,
4,
1.3);
22129 -- this example relies on the date-plus-integer operator:
22130 SELECT current_date + s.a AS dates FROM generate_series(
0,
14,
7) AS s(a);
22138 SELECT * FROM generate_series('
2008-
03-
01 00:
00'::timestamp,
22139 '
2008-
03-
04 12:
00', '
10 hours');
22141 ---------------------
22142 2008-
03-
01 00:
00:
00
22143 2008-
03-
01 10:
00:
00
22144 2008-
03-
01 20:
00:
00
22145 2008-
03-
02 06:
00:
00
22146 2008-
03-
02 16:
00:
00
22147 2008-
03-
03 02:
00:
00
22148 2008-
03-
03 12:
00:
00
22149 2008-
03-
03 22:
00:
00
22150 2008-
03-
04 08:
00:
00
22153 -- this example assumes that TimeZone is set to UTC; note the DST transition:
22154 SELECT * FROM generate_series('
2001-
10-
22 00:
00 -
04:
00'::timestamptz,
22155 '
2001-
11-
01 00:
00 -
05:
00'::timestamptz,
22156 '
1 day'::interval, 'America/New_York');
22158 ------------------------
22159 2001-
10-
22 04:
00:
00+
00
22160 2001-
10-
23 04:
00:
00+
00
22161 2001-
10-
24 04:
00:
00+
00
22162 2001-
10-
25 04:
00:
00+
00
22163 2001-
10-
26 04:
00:
00+
00
22164 2001-
10-
27 04:
00:
00+
00
22165 2001-
10-
28 04:
00:
00+
00
22166 2001-
10-
29 05:
00:
00+
00
22167 2001-
10-
30 05:
00:
00+
00
22168 2001-
10-
31 05:
00:
00+
00
22169 2001-
11-
01 05:
00:
00+
00
22174 <table id=
"functions-srf-subscripts">
22175 <title>Subscript Generating Functions
</title>
22179 <entry role=
"func_table_entry"><para role=
"func_signature">
22190 <entry role=
"func_table_entry"><para role=
"func_signature">
22192 <primary>generate_subscripts
</primary>
22194 <function>generate_subscripts
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>dim
</parameter> <type>integer
</type> )
22195 <returnvalue>setof integer
</returnvalue>
22198 Generates a series comprising the valid subscripts of
22199 the
<parameter>dim
</parameter>'th dimension of the given array.
22204 <entry role=
"func_table_entry"><para role=
"func_signature">
22205 <function>generate_subscripts
</function> (
<parameter>array
</parameter> <type>anyarray
</type>,
<parameter>dim
</parameter> <type>integer
</type>,
<parameter>reverse
</parameter> <type>boolean
</type> )
22206 <returnvalue>setof integer
</returnvalue>
22209 Generates a series comprising the valid subscripts of
22210 the
<parameter>dim
</parameter>'th dimension of the given array.
22211 When
<parameter>reverse
</parameter> is true, returns the series in
22220 <function>generate_subscripts
</function> is a convenience function that generates
22221 the set of valid subscripts for the specified dimension of the given
22223 Zero rows are returned for arrays that do not have the requested dimension,
22224 or if any input is
<literal>NULL
</literal>.
22225 Some examples follow:
22228 SELECT generate_subscripts('{NULL,
1,NULL,
2}'::int[],
1) AS s;
22237 -- presenting an array, the subscript and the subscripted
22238 -- value requires a subquery:
22239 SELECT * FROM arrays;
22241 --------------------
22246 SELECT a AS array, s AS subscript, a[s] AS value
22247 FROM (SELECT generate_subscripts(a,
1) AS s, a FROM arrays) foo;
22248 array | subscript | value
22249 ---------------+-----------+-------
22252 {
100,
200,
300} |
1 |
100
22253 {
100,
200,
300} |
2 |
200
22254 {
100,
200,
300} |
3 |
300
22257 -- unnest a
2D array:
22258 CREATE OR REPLACE FUNCTION unnest2(anyarray)
22259 RETURNS SETOF anyelement AS $$
22261 from generate_subscripts($
1,
1) g1(i),
22262 generate_subscripts($
1,
2) g2(j);
22263 $$ LANGUAGE sql IMMUTABLE;
22265 SELECT * FROM unnest2(ARRAY[[
1,
2],[
3,
4]]);
22277 <primary>ordinality
</primary>
22281 When a function in the
<literal>FROM
</literal> clause is suffixed
22282 by
<literal>WITH ORDINALITY
</literal>, a
<type>bigint
</type> column is
22283 appended to the function's output column(s), which starts from
1 and
22284 increments by
1 for each row of the function's output.
22285 This is most useful in the case of set returning
22286 functions such as
<function>unnest()
</function>.
22289 -- set returning function WITH ORDINALITY:
22290 SELECT * FROM pg_ls_dir('.') WITH ORDINALITY AS t(ls,n);
22292 -----------------+----
22295 postmaster.opts |
3
22297 postgresql.conf |
5
22318 <sect1 id=
"functions-info">
22319 <title>System Information Functions and Operators
</title>
22322 The functions described in this section are used to obtain various
22323 information about a
<productname>PostgreSQL
</productname> installation.
22326 <sect2 id=
"functions-info-session">
22327 <title>Session Information Functions
</title>
22330 <xref linkend=
"functions-info-session-table"/> shows several
22331 functions that extract session and system information.
22335 In addition to the functions listed in this section, there are a number of
22336 functions related to the statistics system that also provide system
22337 information. See
<xref linkend=
"monitoring-stats-views"/> for more
22341 <table id=
"functions-info-session-table">
22342 <title>Session Information Functions
</title>
22346 <entry role=
"func_table_entry"><para role=
"func_signature">
22357 <entry role=
"func_table_entry"><para role=
"func_signature">
22359 <primary>current_catalog
</primary>
22361 <function>current_catalog
</function>
22362 <returnvalue>name
</returnvalue>
22364 <para role=
"func_signature">
22366 <primary>current_database
</primary>
22368 <function>current_database
</function> ()
22369 <returnvalue>name
</returnvalue>
22372 Returns the name of the current database. (Databases are
22373 called
<quote>catalogs
</quote> in the SQL standard,
22374 so
<function>current_catalog
</function> is the standard's
22380 <entry role=
"func_table_entry"><para role=
"func_signature">
22382 <primary>current_query
</primary>
22384 <function>current_query
</function> ()
22385 <returnvalue>text
</returnvalue>
22388 Returns the text of the currently executing query, as submitted
22389 by the client (which might contain more than one statement).
22394 <entry role=
"func_table_entry"><para role=
"func_signature">
22396 <primary>current_role
</primary>
22398 <function>current_role
</function>
22399 <returnvalue>name
</returnvalue>
22402 This is equivalent to
<function>current_user
</function>.
22407 <entry role=
"func_table_entry"><para role=
"func_signature">
22409 <primary>current_schema
</primary>
22412 <primary>schema
</primary>
22413 <secondary>current
</secondary>
22415 <function>current_schema
</function>
22416 <returnvalue>name
</returnvalue>
22418 <para role=
"func_signature">
22419 <function>current_schema
</function> ()
22420 <returnvalue>name
</returnvalue>
22423 Returns the name of the schema that is first in the search path (or a
22424 null value if the search path is empty). This is the schema that will
22425 be used for any tables or other named objects that are created without
22426 specifying a target schema.
22431 <entry role=
"func_table_entry"><para role=
"func_signature">
22433 <primary>current_schemas
</primary>
22436 <primary>search path
</primary>
22437 <secondary>current
</secondary>
22439 <function>current_schemas
</function> (
<parameter>include_implicit
</parameter> <type>boolean
</type> )
22440 <returnvalue>name[]
</returnvalue>
22443 Returns an array of the names of all schemas presently in the
22444 effective search path, in their priority order. (Items in the current
22445 <xref linkend=
"guc-search-path"/> setting that do not correspond to
22446 existing, searchable schemas are omitted.) If the Boolean argument
22447 is
<literal>true
</literal>, then implicitly-searched system schemas
22448 such as
<literal>pg_catalog
</literal> are included in the result.
22453 <entry role=
"func_table_entry"><para role=
"func_signature">
22455 <primary>current_user
</primary>
22458 <primary>user
</primary>
22459 <secondary>current
</secondary>
22461 <function>current_user
</function>
22462 <returnvalue>name
</returnvalue>
22465 Returns the user name of the current execution context.
22470 <entry role=
"func_table_entry"><para role=
"func_signature">
22472 <primary>inet_client_addr
</primary>
22474 <function>inet_client_addr
</function> ()
22475 <returnvalue>inet
</returnvalue>
22478 Returns the IP address of the current client,
22479 or
<literal>NULL
</literal> if the current connection is via a
22480 Unix-domain socket.
22485 <entry role=
"func_table_entry"><para role=
"func_signature">
22487 <primary>inet_client_port
</primary>
22489 <function>inet_client_port
</function> ()
22490 <returnvalue>integer
</returnvalue>
22493 Returns the IP port number of the current client,
22494 or
<literal>NULL
</literal> if the current connection is via a
22495 Unix-domain socket.
22500 <entry role=
"func_table_entry"><para role=
"func_signature">
22502 <primary>inet_server_addr
</primary>
22504 <function>inet_server_addr
</function> ()
22505 <returnvalue>inet
</returnvalue>
22508 Returns the IP address on which the server accepted the current
22510 or
<literal>NULL
</literal> if the current connection is via a
22511 Unix-domain socket.
22516 <entry role=
"func_table_entry"><para role=
"func_signature">
22518 <primary>inet_server_port
</primary>
22520 <function>inet_server_port
</function> ()
22521 <returnvalue>integer
</returnvalue>
22524 Returns the IP port number on which the server accepted the current
22526 or
<literal>NULL
</literal> if the current connection is via a
22527 Unix-domain socket.
22532 <entry role=
"func_table_entry"><para role=
"func_signature">
22534 <primary>pg_backend_pid
</primary>
22536 <function>pg_backend_pid
</function> ()
22537 <returnvalue>integer
</returnvalue>
22540 Returns the process ID of the server process attached to the current
22546 <entry role=
"func_table_entry"><para role=
"func_signature">
22548 <primary>pg_blocking_pids
</primary>
22550 <function>pg_blocking_pids
</function> (
<type>integer
</type> )
22551 <returnvalue>integer[]
</returnvalue>
22554 Returns an array of the process ID(s) of the sessions that are
22555 blocking the server process with the specified process ID from
22556 acquiring a lock, or an empty array if there is no such server process
22557 or it is not blocked.
22560 One server process blocks another if it either holds a lock that
22561 conflicts with the blocked process's lock request (hard block), or is
22562 waiting for a lock that would conflict with the blocked process's lock
22563 request and is ahead of it in the wait queue (soft block). When using
22564 parallel queries the result always lists client-visible process IDs
22565 (that is,
<function>pg_backend_pid
</function> results) even if the
22566 actual lock is held or awaited by a child worker process. As a result
22567 of that, there may be duplicated PIDs in the result. Also note that
22568 when a prepared transaction holds a conflicting lock, it will be
22569 represented by a zero process ID.
22572 Frequent calls to this function could have some impact on database
22573 performance, because it needs exclusive access to the lock manager's
22574 shared state for a short time.
22579 <entry role=
"func_table_entry"><para role=
"func_signature">
22581 <primary>pg_conf_load_time
</primary>
22583 <function>pg_conf_load_time
</function> ()
22584 <returnvalue>timestamp with time zone
</returnvalue>
22587 Returns the time when the server configuration files were last loaded.
22588 If the current session was alive at the time, this will be the time
22589 when the session itself re-read the configuration files (so the
22590 reading will vary a little in different sessions). Otherwise it is
22591 the time when the postmaster process re-read the configuration files.
22596 <entry role=
"func_table_entry"><para role=
"func_signature">
22598 <primary>pg_current_logfile
</primary>
22601 <primary>Logging
</primary>
22602 <secondary>pg_current_logfile function
</secondary>
22605 <primary>current_logfiles
</primary>
22606 <secondary>and the pg_current_logfile function
</secondary>
22609 <primary>Logging
</primary>
22610 <secondary>current_logfiles file and the pg_current_logfile
22611 function
</secondary>
22613 <function>pg_current_logfile
</function> (
<optional> <type>text
</type> </optional> )
22614 <returnvalue>text
</returnvalue>
22617 Returns the path name of the log file currently in use by the logging
22618 collector. The path includes the
<xref linkend=
"guc-log-directory"/>
22619 directory and the individual log file name. The result
22620 is
<literal>NULL
</literal> if the logging collector is disabled.
22621 When multiple log files exist, each in a different
22622 format,
<function>pg_current_logfile
</function> without an argument
22623 returns the path of the file having the first format found in the
22624 ordered list:
<literal>stderr
</literal>,
22625 <literal>csvlog
</literal>,
<literal>jsonlog
</literal>.
22626 <literal>NULL
</literal> is returned if no log file has any of these
22628 To request information about a specific log file format, supply
22629 either
<literal>csvlog
</literal>,
<literal>jsonlog
</literal> or
22630 <literal>stderr
</literal> as the
22631 value of the optional parameter. The result is
<literal>NULL
</literal>
22632 if the log format requested is not configured in
22633 <xref linkend=
"guc-log-destination"/>.
22634 The result reflects the contents of
22635 the
<filename>current_logfiles
</filename> file.
22640 <entry role=
"func_table_entry"><para role=
"func_signature">
22642 <primary>pg_my_temp_schema
</primary>
22644 <function>pg_my_temp_schema
</function> ()
22645 <returnvalue>oid
</returnvalue>
22648 Returns the OID of the current session's temporary schema, or zero if
22649 it has none (because it has not created any temporary tables).
22654 <entry role=
"func_table_entry"><para role=
"func_signature">
22656 <primary>pg_is_other_temp_schema
</primary>
22658 <function>pg_is_other_temp_schema
</function> (
<type>oid
</type> )
22659 <returnvalue>boolean
</returnvalue>
22662 Returns true if the given OID is the OID of another session's
22663 temporary schema. (This can be useful, for example, to exclude other
22664 sessions' temporary tables from a catalog display.)
22669 <entry role=
"func_table_entry"><para role=
"func_signature">
22671 <primary>pg_jit_available
</primary>
22673 <function>pg_jit_available
</function> ()
22674 <returnvalue>boolean
</returnvalue>
22677 Returns true if a
<acronym>JIT
</acronym> compiler extension is
22678 available (see
<xref linkend=
"jit"/>) and the
22679 <xref linkend=
"guc-jit"/> configuration parameter is set to
22680 <literal>on
</literal>.
22685 <entry role=
"func_table_entry"><para role=
"func_signature">
22687 <primary>pg_listening_channels
</primary>
22689 <function>pg_listening_channels
</function> ()
22690 <returnvalue>setof text
</returnvalue>
22693 Returns the set of names of asynchronous notification channels that
22694 the current session is listening to.
22699 <entry role=
"func_table_entry"><para role=
"func_signature">
22701 <primary>pg_notification_queue_usage
</primary>
22703 <function>pg_notification_queue_usage
</function> ()
22704 <returnvalue>double precision
</returnvalue>
22707 Returns the fraction (
0–1) of the asynchronous notification
22708 queue's maximum size that is currently occupied by notifications that
22709 are waiting to be processed.
22710 See
<xref linkend=
"sql-listen"/> and
<xref linkend=
"sql-notify"/>
22711 for more information.
22716 <entry role=
"func_table_entry"><para role=
"func_signature">
22718 <primary>pg_postmaster_start_time
</primary>
22720 <function>pg_postmaster_start_time
</function> ()
22721 <returnvalue>timestamp with time zone
</returnvalue>
22724 Returns the time when the server started.
22729 <entry role=
"func_table_entry"><para role=
"func_signature">
22731 <primary>pg_safe_snapshot_blocking_pids
</primary>
22733 <function>pg_safe_snapshot_blocking_pids
</function> (
<type>integer
</type> )
22734 <returnvalue>integer[]
</returnvalue>
22737 Returns an array of the process ID(s) of the sessions that are blocking
22738 the server process with the specified process ID from acquiring a safe
22739 snapshot, or an empty array if there is no such server process or it
22743 A session running a
<literal>SERIALIZABLE
</literal> transaction blocks
22744 a
<literal>SERIALIZABLE READ ONLY DEFERRABLE
</literal> transaction
22745 from acquiring a snapshot until the latter determines that it is safe
22746 to avoid taking any predicate locks. See
22747 <xref linkend=
"xact-serializable"/> for more information about
22748 serializable and deferrable transactions.
22751 Frequent calls to this function could have some impact on database
22752 performance, because it needs access to the predicate lock manager's
22753 shared state for a short time.
22758 <entry role=
"func_table_entry"><para role=
"func_signature">
22760 <primary>pg_trigger_depth
</primary>
22762 <function>pg_trigger_depth
</function> ()
22763 <returnvalue>integer
</returnvalue>
22766 Returns the current nesting level
22767 of
<productname>PostgreSQL
</productname> triggers (
0 if not called,
22768 directly or indirectly, from inside a trigger).
22773 <entry role=
"func_table_entry"><para role=
"func_signature">
22775 <primary>session_user
</primary>
22777 <function>session_user
</function>
22778 <returnvalue>name
</returnvalue>
22781 Returns the session user's name.
22786 <entry role=
"func_table_entry"><para role=
"func_signature">
22788 <primary>system_user
</primary>
22790 <function>system_user
</function>
22791 <returnvalue>text
</returnvalue>
22794 Returns the authentication method and the identity (if any) that the
22795 user presented during the authentication cycle before they were
22796 assigned a database role. It is represented as
22797 <literal>auth_method:identity
</literal> or
22798 <literal>NULL
</literal> if the user has not been authenticated (for
22799 example if
<link linkend=
"auth-trust">Trust authentication
</link> has
22805 <entry role=
"func_table_entry"><para role=
"func_signature">
22807 <primary>user
</primary>
22809 <function>user
</function>
22810 <returnvalue>name
</returnvalue>
22813 This is equivalent to
<function>current_user
</function>.
22818 <entry role=
"func_table_entry"><para role=
"func_signature">
22820 <primary>version
</primary>
22822 <function>version
</function> ()
22823 <returnvalue>text
</returnvalue>
22826 Returns a string describing the
<productname>PostgreSQL
</productname>
22827 server's version. You can also get this information from
22828 <xref linkend=
"guc-server-version"/>, or for a machine-readable
22829 version use
<xref linkend=
"guc-server-version-num"/>. Software
22830 developers should use
<varname>server_version_num
</varname> (available
22831 since
8.2) or
<xref linkend=
"libpq-PQserverVersion"/> instead of
22832 parsing the text version.
22841 <function>current_catalog
</function>,
22842 <function>current_role
</function>,
22843 <function>current_schema
</function>,
22844 <function>current_user
</function>,
22845 <function>session_user
</function>,
22846 and
<function>user
</function> have special syntactic status
22847 in
<acronym>SQL
</acronym>: they must be called without trailing
22848 parentheses. In PostgreSQL, parentheses can optionally be used with
22849 <function>current_schema
</function>, but not with the others.
22854 The
<function>session_user
</function> is normally the user who initiated
22855 the current database connection; but superusers can change this setting
22856 with
<xref linkend=
"sql-set-session-authorization"/>.
22857 The
<function>current_user
</function> is the user identifier
22858 that is applicable for permission checking. Normally it is equal
22859 to the session user, but it can be changed with
22860 <xref linkend=
"sql-set-role"/>.
22861 It also changes during the execution of
22862 functions with the attribute
<literal>SECURITY DEFINER
</literal>.
22863 In Unix parlance, the session user is the
<quote>real user
</quote> and
22864 the current user is the
<quote>effective user
</quote>.
22865 <function>current_role
</function> and
<function>user
</function> are
22866 synonyms for
<function>current_user
</function>. (The SQL standard draws
22867 a distinction between
<function>current_role
</function>
22868 and
<function>current_user
</function>, but
<productname>PostgreSQL
</productname>
22869 does not, since it unifies users and roles into a single kind of entity.)
22874 <sect2 id=
"functions-info-access">
22875 <title>Access Privilege Inquiry Functions
</title>
22878 <primary>privilege
</primary>
22879 <secondary>querying
</secondary>
22883 <xref linkend=
"functions-info-access-table"/> lists functions that
22884 allow querying object access privileges programmatically.
22885 (See
<xref linkend=
"ddl-priv"/> for more information about
22887 In these functions, the user whose privileges are being inquired about
22888 can be specified by name or by OID
22889 (
<structname>pg_authid
</structname>.
<structfield>oid
</structfield>), or if
22890 the name is given as
<literal>public
</literal> then the privileges of the
22891 PUBLIC pseudo-role are checked. Also, the
<parameter>user
</parameter>
22892 argument can be omitted entirely, in which case
22893 the
<function>current_user
</function> is assumed.
22894 The object that is being inquired about can be specified either by name or
22895 by OID, too. When specifying by name, a schema name can be included if
22897 The access privilege of interest is specified by a text string, which must
22898 evaluate to one of the appropriate privilege keywords for the object's type
22899 (e.g.,
<literal>SELECT
</literal>). Optionally,
<literal>WITH GRANT
22900 OPTION
</literal> can be added to a privilege type to test whether the
22901 privilege is held with grant option. Also, multiple privilege types can be
22902 listed separated by commas, in which case the result will be true if any of
22903 the listed privileges is held. (Case of the privilege string is not
22904 significant, and extra whitespace is allowed between but not within
22908 SELECT has_table_privilege('myschema.mytable', 'select');
22909 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
22913 <table id=
"functions-info-access-table">
22914 <title>Access Privilege Inquiry Functions
</title>
22918 <entry role=
"func_table_entry"><para role=
"func_signature">
22929 <entry role=
"func_table_entry"><para role=
"func_signature">
22931 <primary>has_any_column_privilege
</primary>
22933 <function>has_any_column_privilege
</function> (
22934 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
22935 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
22936 <parameter>privilege
</parameter> <type>text
</type> )
22937 <returnvalue>boolean
</returnvalue>
22940 Does user have privilege for any column of table?
22941 This succeeds either if the privilege is held for the whole table, or
22942 if there is a column-level grant of the privilege for at least one
22944 Allowable privilege types are
22945 <literal>SELECT
</literal>,
<literal>INSERT
</literal>,
22946 <literal>UPDATE
</literal>, and
<literal>REFERENCES
</literal>.
22951 <entry role=
"func_table_entry"><para role=
"func_signature">
22953 <primary>has_column_privilege
</primary>
22955 <function>has_column_privilege
</function> (
22956 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
22957 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
22958 <parameter>column
</parameter> <type>text
</type> or
<type>smallint
</type>,
22959 <parameter>privilege
</parameter> <type>text
</type> )
22960 <returnvalue>boolean
</returnvalue>
22963 Does user have privilege for the specified table column?
22964 This succeeds either if the privilege is held for the whole table, or
22965 if there is a column-level grant of the privilege for the column.
22966 The column can be specified by name or by attribute number
22967 (
<structname>pg_attribute
</structname>.
<structfield>attnum
</structfield>).
22968 Allowable privilege types are
22969 <literal>SELECT
</literal>,
<literal>INSERT
</literal>,
22970 <literal>UPDATE
</literal>, and
<literal>REFERENCES
</literal>.
22975 <entry role=
"func_table_entry"><para role=
"func_signature">
22977 <primary>has_database_privilege
</primary>
22979 <function>has_database_privilege
</function> (
22980 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
22981 <parameter>database
</parameter> <type>text
</type> or
<type>oid
</type>,
22982 <parameter>privilege
</parameter> <type>text
</type> )
22983 <returnvalue>boolean
</returnvalue>
22986 Does user have privilege for database?
22987 Allowable privilege types are
22988 <literal>CREATE
</literal>,
22989 <literal>CONNECT
</literal>,
22990 <literal>TEMPORARY
</literal>, and
22991 <literal>TEMP
</literal> (which is equivalent to
22992 <literal>TEMPORARY
</literal>).
22997 <entry role=
"func_table_entry"><para role=
"func_signature">
22999 <primary>has_foreign_data_wrapper_privilege
</primary>
23001 <function>has_foreign_data_wrapper_privilege
</function> (
23002 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23003 <parameter>fdw
</parameter> <type>text
</type> or
<type>oid
</type>,
23004 <parameter>privilege
</parameter> <type>text
</type> )
23005 <returnvalue>boolean
</returnvalue>
23008 Does user have privilege for foreign-data wrapper?
23009 The only allowable privilege type is
<literal>USAGE
</literal>.
23014 <entry role=
"func_table_entry"><para role=
"func_signature">
23016 <primary>has_function_privilege
</primary>
23018 <function>has_function_privilege
</function> (
23019 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23020 <parameter>function
</parameter> <type>text
</type> or
<type>oid
</type>,
23021 <parameter>privilege
</parameter> <type>text
</type> )
23022 <returnvalue>boolean
</returnvalue>
23025 Does user have privilege for function?
23026 The only allowable privilege type is
<literal>EXECUTE
</literal>.
23029 When specifying a function by name rather than by OID, the allowed
23030 input is the same as for the
<type>regprocedure
</type> data type (see
23031 <xref linkend=
"datatype-oid"/>).
23034 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
23040 <entry role=
"func_table_entry"><para role=
"func_signature">
23042 <primary>has_language_privilege
</primary>
23044 <function>has_language_privilege
</function> (
23045 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23046 <parameter>language
</parameter> <type>text
</type> or
<type>oid
</type>,
23047 <parameter>privilege
</parameter> <type>text
</type> )
23048 <returnvalue>boolean
</returnvalue>
23051 Does user have privilege for language?
23052 The only allowable privilege type is
<literal>USAGE
</literal>.
23057 <entry role=
"func_table_entry"><para role=
"func_signature">
23059 <primary>has_parameter_privilege
</primary>
23061 <function>has_parameter_privilege
</function> (
23062 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23063 <parameter>parameter
</parameter> <type>text
</type>,
23064 <parameter>privilege
</parameter> <type>text
</type> )
23065 <returnvalue>boolean
</returnvalue>
23068 Does user have privilege for configuration parameter?
23069 The parameter name is case-insensitive.
23070 Allowable privilege types are
<literal>SET
</literal>
23071 and
<literal>ALTER SYSTEM
</literal>.
23076 <entry role=
"func_table_entry"><para role=
"func_signature">
23078 <primary>has_schema_privilege
</primary>
23080 <function>has_schema_privilege
</function> (
23081 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23082 <parameter>schema
</parameter> <type>text
</type> or
<type>oid
</type>,
23083 <parameter>privilege
</parameter> <type>text
</type> )
23084 <returnvalue>boolean
</returnvalue>
23087 Does user have privilege for schema?
23088 Allowable privilege types are
23089 <literal>CREATE
</literal> and
23090 <literal>USAGE
</literal>.
23095 <entry role=
"func_table_entry"><para role=
"func_signature">
23097 <primary>has_sequence_privilege
</primary>
23099 <function>has_sequence_privilege
</function> (
23100 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23101 <parameter>sequence
</parameter> <type>text
</type> or
<type>oid
</type>,
23102 <parameter>privilege
</parameter> <type>text
</type> )
23103 <returnvalue>boolean
</returnvalue>
23106 Does user have privilege for sequence?
23107 Allowable privilege types are
23108 <literal>USAGE
</literal>,
23109 <literal>SELECT
</literal>, and
23110 <literal>UPDATE
</literal>.
23115 <entry role=
"func_table_entry"><para role=
"func_signature">
23117 <primary>has_server_privilege
</primary>
23119 <function>has_server_privilege
</function> (
23120 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23121 <parameter>server
</parameter> <type>text
</type> or
<type>oid
</type>,
23122 <parameter>privilege
</parameter> <type>text
</type> )
23123 <returnvalue>boolean
</returnvalue>
23126 Does user have privilege for foreign server?
23127 The only allowable privilege type is
<literal>USAGE
</literal>.
23132 <entry role=
"func_table_entry"><para role=
"func_signature">
23134 <primary>has_table_privilege
</primary>
23136 <function>has_table_privilege
</function> (
23137 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23138 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type>,
23139 <parameter>privilege
</parameter> <type>text
</type> )
23140 <returnvalue>boolean
</returnvalue>
23143 Does user have privilege for table?
23144 Allowable privilege types
23145 are
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
23146 <literal>UPDATE
</literal>,
<literal>DELETE
</literal>,
23147 <literal>TRUNCATE
</literal>,
<literal>REFERENCES
</literal>,
23148 <literal>TRIGGER
</literal>, and
<literal>MAINTAIN
</literal>.
23153 <entry role=
"func_table_entry"><para role=
"func_signature">
23155 <primary>has_tablespace_privilege
</primary>
23157 <function>has_tablespace_privilege
</function> (
23158 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23159 <parameter>tablespace
</parameter> <type>text
</type> or
<type>oid
</type>,
23160 <parameter>privilege
</parameter> <type>text
</type> )
23161 <returnvalue>boolean
</returnvalue>
23164 Does user have privilege for tablespace?
23165 The only allowable privilege type is
<literal>CREATE
</literal>.
23170 <entry role=
"func_table_entry"><para role=
"func_signature">
23172 <primary>has_type_privilege
</primary>
23174 <function>has_type_privilege
</function> (
23175 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23176 <parameter>type
</parameter> <type>text
</type> or
<type>oid
</type>,
23177 <parameter>privilege
</parameter> <type>text
</type> )
23178 <returnvalue>boolean
</returnvalue>
23181 Does user have privilege for data type?
23182 The only allowable privilege type is
<literal>USAGE
</literal>.
23183 When specifying a type by name rather than by OID, the allowed input
23184 is the same as for the
<type>regtype
</type> data type (see
23185 <xref linkend=
"datatype-oid"/>).
23190 <entry role=
"func_table_entry"><para role=
"func_signature">
23192 <primary>pg_has_role
</primary>
23194 <function>pg_has_role
</function> (
23195 <optional> <parameter>user
</parameter> <type>name
</type> or
<type>oid
</type>,
</optional>
23196 <parameter>role
</parameter> <type>text
</type> or
<type>oid
</type>,
23197 <parameter>privilege
</parameter> <type>text
</type> )
23198 <returnvalue>boolean
</returnvalue>
23201 Does user have privilege for role?
23202 Allowable privilege types are
23203 <literal>MEMBER
</literal>,
<literal>USAGE
</literal>,
23204 and
<literal>SET
</literal>.
23205 <literal>MEMBER
</literal> denotes direct or indirect membership in
23206 the role without regard to what specific privileges may be conferred.
23207 <literal>USAGE
</literal> denotes whether the privileges of the role
23208 are immediately available without doing
<command>SET ROLE
</command>,
23209 while
<literal>SET
</literal> denotes whether it is possible to change
23210 to the role using the
<literal>SET ROLE
</literal> command.
23211 This function does not allow the special case of
23212 setting
<parameter>user
</parameter> to
<literal>public
</literal>,
23213 because the PUBLIC pseudo-role can never be a member of real roles.
23218 <entry role=
"func_table_entry"><para role=
"func_signature">
23220 <primary>row_security_active
</primary>
23222 <function>row_security_active
</function> (
23223 <parameter>table
</parameter> <type>text
</type> or
<type>oid
</type> )
23224 <returnvalue>boolean
</returnvalue>
23227 Is row-level security active for the specified table in the context of
23228 the current user and current environment?
23236 <xref linkend=
"functions-aclitem-op-table"/> shows the operators
23237 available for the
<type>aclitem
</type> type, which is the catalog
23238 representation of access privileges. See
<xref linkend=
"ddl-priv"/>
23239 for information about how to read access privilege values.
23242 <table id=
"functions-aclitem-op-table">
23243 <title><type>aclitem
</type> Operators
</title>
23247 <entry role=
"func_table_entry"><para role=
"func_signature">
23261 <entry role=
"func_table_entry"><para role=
"func_signature">
23263 <primary>aclitemeq
</primary>
23265 <type>aclitem
</type> <literal>=
</literal> <type>aclitem
</type>
23266 <returnvalue>boolean
</returnvalue>
23269 Are
<type>aclitem
</type>s equal? (Notice that
23270 type
<type>aclitem
</type> lacks the usual set of comparison
23271 operators; it has only equality. In turn,
<type>aclitem
</type>
23272 arrays can only be compared for equality.)
23275 <literal>'calvin=r*w/hobbes'::aclitem = 'calvin=r*w*/hobbes'::aclitem
</literal>
23276 <returnvalue>f
</returnvalue>
23281 <entry role=
"func_table_entry"><para role=
"func_signature">
23283 <primary>aclcontains
</primary>
23285 <type>aclitem[]
</type> <literal>@
></literal> <type>aclitem
</type>
23286 <returnvalue>boolean
</returnvalue>
23289 Does array contain the specified privileges? (This is true if there
23290 is an array entry that matches the
<type>aclitem
</type>'s grantee and
23291 grantor, and has at least the specified set of privileges.)
23294 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] @
> 'calvin=r*/hobbes'::aclitem
</literal>
23295 <returnvalue>t
</returnvalue>
23300 <entry role=
"func_table_entry"><para role=
"func_signature">
23301 <type>aclitem[]
</type> <literal>~
</literal> <type>aclitem
</type>
23302 <returnvalue>boolean
</returnvalue>
23305 This is a deprecated alias for
<literal>@
></literal>.
23308 <literal>'{calvin=r*w/hobbes,hobbes=r*w*/postgres}'::aclitem[] ~ 'calvin=r*/hobbes'::aclitem
</literal>
23309 <returnvalue>t
</returnvalue>
23317 <xref linkend=
"functions-aclitem-fn-table"/> shows some additional
23318 functions to manage the
<type>aclitem
</type> type.
23321 <table id=
"functions-aclitem-fn-table">
23322 <title><type>aclitem
</type> Functions
</title>
23326 <entry role=
"func_table_entry"><para role=
"func_signature">
23337 <entry role=
"func_table_entry"><para role=
"func_signature">
23339 <primary>acldefault
</primary>
23341 <function>acldefault
</function> (
23342 <parameter>type
</parameter> <type>"char"</type>,
23343 <parameter>ownerId
</parameter> <type>oid
</type> )
23344 <returnvalue>aclitem[]
</returnvalue>
23347 Constructs an
<type>aclitem
</type> array holding the default access
23348 privileges for an object of type
<parameter>type
</parameter> belonging
23349 to the role with OID
<parameter>ownerId
</parameter>. This represents
23350 the access privileges that will be assumed when an object's ACL entry
23351 is null. (The default access privileges are described in
23352 <xref linkend=
"ddl-priv"/>.)
23353 The
<parameter>type
</parameter> parameter must be one of
23354 'c' for
<literal>COLUMN
</literal>,
23355 'r' for
<literal>TABLE
</literal> and table-like objects,
23356 's' for
<literal>SEQUENCE
</literal>,
23357 'd' for
<literal>DATABASE
</literal>,
23358 'f' for
<literal>FUNCTION
</literal> or
<literal>PROCEDURE
</literal>,
23359 'l' for
<literal>LANGUAGE
</literal>,
23360 'L' for
<literal>LARGE OBJECT
</literal>,
23361 'n' for
<literal>SCHEMA
</literal>,
23362 'p' for
<literal>PARAMETER
</literal>,
23363 't' for
<literal>TABLESPACE
</literal>,
23364 'F' for
<literal>FOREIGN DATA WRAPPER
</literal>,
23365 'S' for
<literal>FOREIGN SERVER
</literal>,
23367 'T' for
<literal>TYPE
</literal> or
<literal>DOMAIN
</literal>.
23372 <entry role=
"func_table_entry"><para role=
"func_signature">
23374 <primary>aclexplode
</primary>
23376 <function>aclexplode
</function> (
<type>aclitem[]
</type> )
23377 <returnvalue>setof record
</returnvalue>
23378 (
<parameter>grantor
</parameter> <type>oid
</type>,
23379 <parameter>grantee
</parameter> <type>oid
</type>,
23380 <parameter>privilege_type
</parameter> <type>text
</type>,
23381 <parameter>is_grantable
</parameter> <type>boolean
</type> )
23384 Returns the
<type>aclitem
</type> array as a set of rows.
23385 If the grantee is the pseudo-role PUBLIC, it is represented by zero in
23386 the
<parameter>grantee
</parameter> column. Each granted privilege is
23387 represented as
<literal>SELECT
</literal>,
<literal>INSERT
</literal>,
23388 etc (see
<xref linkend=
"privilege-abbrevs-table"/> for a full list).
23389 Note that each privilege is broken out as a separate row, so
23390 only one keyword appears in the
<parameter>privilege_type
</parameter>
23396 <entry role=
"func_table_entry"><para role=
"func_signature">
23398 <primary>makeaclitem
</primary>
23400 <function>makeaclitem
</function> (
23401 <parameter>grantee
</parameter> <type>oid
</type>,
23402 <parameter>grantor
</parameter> <type>oid
</type>,
23403 <parameter>privileges
</parameter> <type>text
</type>,
23404 <parameter>is_grantable
</parameter> <type>boolean
</type> )
23405 <returnvalue>aclitem
</returnvalue>
23408 Constructs an
<type>aclitem
</type> with the given properties.
23409 <parameter>privileges
</parameter> is a comma-separated list of
23410 privilege names such as
<literal>SELECT
</literal>,
23411 <literal>INSERT
</literal>, etc, all of which are set in the
23412 result. (Case of the privilege string is not significant, and
23413 extra whitespace is allowed between but not within privilege
23423 <sect2 id=
"functions-info-schema">
23424 <title>Schema Visibility Inquiry Functions
</title>
23427 <xref linkend=
"functions-info-schema-table"/> shows functions that
23428 determine whether a certain object is
<firstterm>visible
</firstterm> in the
23429 current schema search path.
23430 For example, a table is said to be visible if its
23431 containing schema is in the search path and no table of the same
23432 name appears earlier in the search path. This is equivalent to the
23433 statement that the table can be referenced by name without explicit
23434 schema qualification. Thus, to list the names of all visible tables:
23436 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
23438 For functions and operators, an object in the search path is said to be
23439 visible if there is no object of the same name
<emphasis>and argument data
23440 type(s)
</emphasis> earlier in the path. For operator classes and families,
23441 both the name and the associated index access method are considered.
23445 <primary>search path
</primary>
23446 <secondary>object visibility
</secondary>
23449 <table id=
"functions-info-schema-table">
23450 <title>Schema Visibility Inquiry Functions
</title>
23454 <entry role=
"func_table_entry"><para role=
"func_signature">
23465 <entry role=
"func_table_entry"><para role=
"func_signature">
23467 <primary>pg_collation_is_visible
</primary>
23469 <function>pg_collation_is_visible
</function> (
<parameter>collation
</parameter> <type>oid
</type> )
23470 <returnvalue>boolean
</returnvalue>
23473 Is collation visible in search path?
23478 <entry role=
"func_table_entry"><para role=
"func_signature">
23480 <primary>pg_conversion_is_visible
</primary>
23482 <function>pg_conversion_is_visible
</function> (
<parameter>conversion
</parameter> <type>oid
</type> )
23483 <returnvalue>boolean
</returnvalue>
23486 Is conversion visible in search path?
23491 <entry role=
"func_table_entry"><para role=
"func_signature">
23493 <primary>pg_function_is_visible
</primary>
23495 <function>pg_function_is_visible
</function> (
<parameter>function
</parameter> <type>oid
</type> )
23496 <returnvalue>boolean
</returnvalue>
23499 Is function visible in search path?
23500 (This also works for procedures and aggregates.)
23505 <entry role=
"func_table_entry"><para role=
"func_signature">
23507 <primary>pg_opclass_is_visible
</primary>
23509 <function>pg_opclass_is_visible
</function> (
<parameter>opclass
</parameter> <type>oid
</type> )
23510 <returnvalue>boolean
</returnvalue>
23513 Is operator class visible in search path?
23518 <entry role=
"func_table_entry"><para role=
"func_signature">
23520 <primary>pg_operator_is_visible
</primary>
23522 <function>pg_operator_is_visible
</function> (
<parameter>operator
</parameter> <type>oid
</type> )
23523 <returnvalue>boolean
</returnvalue>
23526 Is operator visible in search path?
23531 <entry role=
"func_table_entry"><para role=
"func_signature">
23533 <primary>pg_opfamily_is_visible
</primary>
23535 <function>pg_opfamily_is_visible
</function> (
<parameter>opclass
</parameter> <type>oid
</type> )
23536 <returnvalue>boolean
</returnvalue>
23539 Is operator family visible in search path?
23544 <entry role=
"func_table_entry"><para role=
"func_signature">
23546 <primary>pg_statistics_obj_is_visible
</primary>
23548 <function>pg_statistics_obj_is_visible
</function> (
<parameter>stat
</parameter> <type>oid
</type> )
23549 <returnvalue>boolean
</returnvalue>
23552 Is statistics object visible in search path?
23557 <entry role=
"func_table_entry"><para role=
"func_signature">
23559 <primary>pg_table_is_visible
</primary>
23561 <function>pg_table_is_visible
</function> (
<parameter>table
</parameter> <type>oid
</type> )
23562 <returnvalue>boolean
</returnvalue>
23565 Is table visible in search path?
23566 (This works for all types of relations, including views, materialized
23567 views, indexes, sequences and foreign tables.)
23572 <entry role=
"func_table_entry"><para role=
"func_signature">
23574 <primary>pg_ts_config_is_visible
</primary>
23576 <function>pg_ts_config_is_visible
</function> (
<parameter>config
</parameter> <type>oid
</type> )
23577 <returnvalue>boolean
</returnvalue>
23580 Is text search configuration visible in search path?
23585 <entry role=
"func_table_entry"><para role=
"func_signature">
23587 <primary>pg_ts_dict_is_visible
</primary>
23589 <function>pg_ts_dict_is_visible
</function> (
<parameter>dict
</parameter> <type>oid
</type> )
23590 <returnvalue>boolean
</returnvalue>
23593 Is text search dictionary visible in search path?
23598 <entry role=
"func_table_entry"><para role=
"func_signature">
23600 <primary>pg_ts_parser_is_visible
</primary>
23602 <function>pg_ts_parser_is_visible
</function> (
<parameter>parser
</parameter> <type>oid
</type> )
23603 <returnvalue>boolean
</returnvalue>
23606 Is text search parser visible in search path?
23611 <entry role=
"func_table_entry"><para role=
"func_signature">
23613 <primary>pg_ts_template_is_visible
</primary>
23615 <function>pg_ts_template_is_visible
</function> (
<parameter>template
</parameter> <type>oid
</type> )
23616 <returnvalue>boolean
</returnvalue>
23619 Is text search template visible in search path?
23624 <entry role=
"func_table_entry"><para role=
"func_signature">
23626 <primary>pg_type_is_visible
</primary>
23628 <function>pg_type_is_visible
</function> (
<parameter>type
</parameter> <type>oid
</type> )
23629 <returnvalue>boolean
</returnvalue>
23632 Is type (or domain) visible in search path?
23640 All these functions require object OIDs to identify the object to be
23641 checked. If you want to test an object by name, it is convenient to use
23642 the OID alias types (
<type>regclass
</type>,
<type>regtype
</type>,
23643 <type>regprocedure
</type>,
<type>regoperator
</type>,
<type>regconfig
</type>,
23644 or
<type>regdictionary
</type>),
23647 SELECT pg_type_is_visible('myschema.widget'::regtype);
23649 Note that it would not make much sense to test a non-schema-qualified
23650 type name in this way
— if the name can be recognized at all, it must be visible.
23655 <sect2 id=
"functions-info-catalog">
23656 <title>System Catalog Information Functions
</title>
23659 <xref linkend=
"functions-info-catalog-table"/> lists functions that
23660 extract information from the system catalogs.
23663 <table id=
"functions-info-catalog-table">
23664 <title>System Catalog Information Functions
</title>
23668 <entry role=
"func_table_entry"><para role=
"func_signature">
23679 <entry role=
"func_table_entry"><para role=
"func_signature">
23681 <primary>format_type
</primary>
23683 <function>format_type
</function> (
<parameter>type
</parameter> <type>oid
</type>,
<parameter>typemod
</parameter> <type>integer
</type> )
23684 <returnvalue>text
</returnvalue>
23687 Returns the SQL name for a data type that is identified by its type
23688 OID and possibly a type modifier. Pass NULL for the type modifier if
23689 no specific modifier is known.
23694 <entry id=
"pg-char-to-encoding" role=
"func_table_entry"><para role=
"func_signature">
23696 <primary>pg_char_to_encoding
</primary>
23698 <function>pg_char_to_encoding
</function> (
<parameter>encoding
</parameter> <type>name
</type> )
23699 <returnvalue>integer
</returnvalue>
23702 Converts the supplied encoding name into an integer representing the
23703 internal identifier used in some system catalog tables.
23704 Returns
<literal>-
1</literal> if an unknown encoding name is provided.
23709 <entry id=
"pg-encoding-to-char" role=
"func_table_entry"><para role=
"func_signature">
23711 <primary>pg_encoding_to_char
</primary>
23713 <function>pg_encoding_to_char
</function> (
<parameter>encoding
</parameter> <type>integer
</type> )
23714 <returnvalue>name
</returnvalue>
23717 Converts the integer used as the internal identifier of an encoding in some
23718 system catalog tables into a human-readable string.
23719 Returns an empty string if an invalid encoding number is provided.
23724 <entry role=
"func_table_entry"><para role=
"func_signature">
23726 <primary>pg_get_catalog_foreign_keys
</primary>
23728 <function>pg_get_catalog_foreign_keys
</function> ()
23729 <returnvalue>setof record
</returnvalue>
23730 (
<parameter>fktable
</parameter> <type>regclass
</type>,
23731 <parameter>fkcols
</parameter> <type>text[]
</type>,
23732 <parameter>pktable
</parameter> <type>regclass
</type>,
23733 <parameter>pkcols
</parameter> <type>text[]
</type>,
23734 <parameter>is_array
</parameter> <type>boolean
</type>,
23735 <parameter>is_opt
</parameter> <type>boolean
</type> )
23738 Returns a set of records describing the foreign key relationships
23739 that exist within the
<productname>PostgreSQL
</productname> system
23741 The
<parameter>fktable
</parameter> column contains the name of the
23742 referencing catalog, and the
<parameter>fkcols
</parameter> column
23743 contains the name(s) of the referencing column(s). Similarly,
23744 the
<parameter>pktable
</parameter> column contains the name of the
23745 referenced catalog, and the
<parameter>pkcols
</parameter> column
23746 contains the name(s) of the referenced column(s).
23747 If
<parameter>is_array
</parameter> is true, the last referencing
23748 column is an array, each of whose elements should match some entry
23749 in the referenced catalog.
23750 If
<parameter>is_opt
</parameter> is true, the referencing column(s)
23751 are allowed to contain zeroes instead of a valid reference.
23756 <entry role=
"func_table_entry"><para role=
"func_signature">
23758 <primary>pg_get_constraintdef
</primary>
23760 <function>pg_get_constraintdef
</function> (
<parameter>constraint
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
23761 <returnvalue>text
</returnvalue>
23764 Reconstructs the creating command for a constraint.
23765 (This is a decompiled reconstruction, not the original text
23771 <entry role=
"func_table_entry"><para role=
"func_signature">
23773 <primary>pg_get_expr
</primary>
23775 <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> )
23776 <returnvalue>text
</returnvalue>
23779 Decompiles the internal form of an expression stored in the system
23780 catalogs, such as the default value for a column. If the expression
23781 might contain Vars, specify the OID of the relation they refer to as
23782 the second parameter; if no Vars are expected, passing zero is
23788 <entry role=
"func_table_entry"><para role=
"func_signature">
23790 <primary>pg_get_functiondef
</primary>
23792 <function>pg_get_functiondef
</function> (
<parameter>func
</parameter> <type>oid
</type> )
23793 <returnvalue>text
</returnvalue>
23796 Reconstructs the creating command for a function or procedure.
23797 (This is a decompiled reconstruction, not the original text
23799 The result is a complete
<command>CREATE OR REPLACE FUNCTION
</command>
23800 or
<command>CREATE OR REPLACE PROCEDURE
</command> statement.
23805 <entry role=
"func_table_entry"><para role=
"func_signature">
23807 <primary>pg_get_function_arguments
</primary>
23809 <function>pg_get_function_arguments
</function> (
<parameter>func
</parameter> <type>oid
</type> )
23810 <returnvalue>text
</returnvalue>
23813 Reconstructs the argument list of a function or procedure, in the form
23814 it would need to appear in within
<command>CREATE FUNCTION
</command>
23815 (including default values).
23820 <entry role=
"func_table_entry"><para role=
"func_signature">
23822 <primary>pg_get_function_identity_arguments
</primary>
23824 <function>pg_get_function_identity_arguments
</function> (
<parameter>func
</parameter> <type>oid
</type> )
23825 <returnvalue>text
</returnvalue>
23828 Reconstructs the argument list necessary to identify a function or
23829 procedure, in the form it would need to appear in within commands such
23830 as
<command>ALTER FUNCTION
</command>. This form omits default values.
23835 <entry role=
"func_table_entry"><para role=
"func_signature">
23837 <primary>pg_get_function_result
</primary>
23839 <function>pg_get_function_result
</function> (
<parameter>func
</parameter> <type>oid
</type> )
23840 <returnvalue>text
</returnvalue>
23843 Reconstructs the
<literal>RETURNS
</literal> clause of a function, in
23844 the form it would need to appear in within
<command>CREATE
23845 FUNCTION
</command>. Returns
<literal>NULL
</literal> for a procedure.
23850 <entry role=
"func_table_entry"><para role=
"func_signature">
23852 <primary>pg_get_indexdef
</primary>
23854 <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> )
23855 <returnvalue>text
</returnvalue>
23858 Reconstructs the creating command for an index.
23859 (This is a decompiled reconstruction, not the original text
23860 of the command.) If
<parameter>column
</parameter> is supplied and is
23861 not zero, only the definition of that column is reconstructed.
23866 <entry role=
"func_table_entry"><para role=
"func_signature">
23868 <primary>pg_get_keywords
</primary>
23870 <function>pg_get_keywords
</function> ()
23871 <returnvalue>setof record
</returnvalue>
23872 (
<parameter>word
</parameter> <type>text
</type>,
23873 <parameter>catcode
</parameter> <type>"char"</type>,
23874 <parameter>barelabel
</parameter> <type>boolean
</type>,
23875 <parameter>catdesc
</parameter> <type>text
</type>,
23876 <parameter>baredesc
</parameter> <type>text
</type> )
23879 Returns a set of records describing the SQL keywords recognized by the
23880 server. The
<parameter>word
</parameter> column contains the
23881 keyword. The
<parameter>catcode
</parameter> column contains a
23882 category code:
<literal>U
</literal> for an unreserved
23883 keyword,
<literal>C
</literal> for a keyword that can be a column
23884 name,
<literal>T
</literal> for a keyword that can be a type or
23885 function name, or
<literal>R
</literal> for a fully reserved keyword.
23886 The
<parameter>barelabel
</parameter> column
23887 contains
<literal>true
</literal> if the keyword can be used as
23888 a
<quote>bare
</quote> column label in
<command>SELECT
</command> lists,
23889 or
<literal>false
</literal> if it can only be used
23890 after
<literal>AS
</literal>.
23891 The
<parameter>catdesc
</parameter> column contains a
23892 possibly-localized string describing the keyword's category.
23893 The
<parameter>baredesc
</parameter> column contains a
23894 possibly-localized string describing the keyword's column label status.
23899 <entry role=
"func_table_entry"><para role=
"func_signature">
23901 <primary>pg_get_partkeydef
</primary>
23903 <function>pg_get_partkeydef
</function> (
<parameter>table
</parameter> <type>oid
</type> )
23904 <returnvalue>text
</returnvalue>
23907 Reconstructs the definition of a partitioned table's partition
23908 key, in the form it would have in the
<literal>PARTITION
23909 BY
</literal> clause of
<command>CREATE TABLE
</command>.
23910 (This is a decompiled reconstruction, not the original text
23916 <entry role=
"func_table_entry"><para role=
"func_signature">
23918 <primary>pg_get_ruledef
</primary>
23920 <function>pg_get_ruledef
</function> (
<parameter>rule
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
23921 <returnvalue>text
</returnvalue>
23924 Reconstructs the creating command for a rule.
23925 (This is a decompiled reconstruction, not the original text
23931 <entry role=
"func_table_entry"><para role=
"func_signature">
23933 <primary>pg_get_serial_sequence
</primary>
23935 <function>pg_get_serial_sequence
</function> (
<parameter>table
</parameter> <type>text
</type>,
<parameter>column
</parameter> <type>text
</type> )
23936 <returnvalue>text
</returnvalue>
23939 Returns the name of the sequence associated with a column,
23940 or NULL if no sequence is associated with the column.
23941 If the column is an identity column, the associated sequence is the
23942 sequence internally created for that column.
23943 For columns created using one of the serial types
23944 (
<type>serial
</type>,
<type>smallserial
</type>,
<type>bigserial
</type>),
23945 it is the sequence created for that serial column definition.
23946 In the latter case, the association can be modified or removed
23947 with
<command>ALTER SEQUENCE OWNED BY
</command>.
23948 (This function probably should have been
23949 called
<function>pg_get_owned_sequence
</function>; its current name
23950 reflects the fact that it has historically been used with serial-type
23951 columns.) The first parameter is a table name with optional
23952 schema, and the second parameter is a column name. Because the first
23953 parameter potentially contains both schema and table names, it is
23954 parsed per usual SQL rules, meaning it is lower-cased by default.
23955 The second parameter, being just a column name, is treated literally
23956 and so has its case preserved. The result is suitably formatted
23957 for passing to the sequence functions (see
23958 <xref linkend=
"functions-sequence"/>).
23961 A typical use is in reading the current value of the sequence for an
23962 identity or serial column, for example:
23964 SELECT currval(pg_get_serial_sequence('sometable', 'id'));
23970 <entry role=
"func_table_entry"><para role=
"func_signature">
23972 <primary>pg_get_statisticsobjdef
</primary>
23974 <function>pg_get_statisticsobjdef
</function> (
<parameter>statobj
</parameter> <type>oid
</type> )
23975 <returnvalue>text
</returnvalue>
23978 Reconstructs the creating command for an extended statistics object.
23979 (This is a decompiled reconstruction, not the original text
23985 <entry role=
"func_table_entry"><para role=
"func_signature">
23987 <primary>pg_get_triggerdef
</primary>
23989 <function>pg_get_triggerdef
</function> (
<parameter>trigger
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
23990 <returnvalue>text
</returnvalue>
23993 Reconstructs the creating command for a trigger.
23994 (This is a decompiled reconstruction, not the original text
24000 <entry role=
"func_table_entry"><para role=
"func_signature">
24002 <primary>pg_get_userbyid
</primary>
24004 <function>pg_get_userbyid
</function> (
<parameter>role
</parameter> <type>oid
</type> )
24005 <returnvalue>name
</returnvalue>
24008 Returns a role's name given its OID.
24013 <entry role=
"func_table_entry"><para role=
"func_signature">
24015 <primary>pg_get_viewdef
</primary>
24017 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>oid
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
24018 <returnvalue>text
</returnvalue>
24021 Reconstructs the underlying
<command>SELECT
</command> command for a
24022 view or materialized view. (This is a decompiled reconstruction, not
24023 the original text of the command.)
24028 <entry role=
"func_table_entry"><para role=
"func_signature">
24029 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>oid
</type>,
<parameter>wrap_column
</parameter> <type>integer
</type> )
24030 <returnvalue>text
</returnvalue>
24033 Reconstructs the underlying
<command>SELECT
</command> command for a
24034 view or materialized view. (This is a decompiled reconstruction, not
24035 the original text of the command.) In this form of the function,
24036 pretty-printing is always enabled, and long lines are wrapped to try
24037 to keep them shorter than the specified number of columns.
24042 <entry role=
"func_table_entry"><para role=
"func_signature">
24043 <function>pg_get_viewdef
</function> (
<parameter>view
</parameter> <type>text
</type> <optional>,
<parameter>pretty
</parameter> <type>boolean
</type> </optional> )
24044 <returnvalue>text
</returnvalue>
24047 Reconstructs the underlying
<command>SELECT
</command> command for a
24048 view or materialized view, working from a textual name for the view
24049 rather than its OID. (This is deprecated; use the OID variant
24055 <entry role=
"func_table_entry"><para role=
"func_signature">
24057 <primary>pg_index_column_has_property
</primary>
24059 <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> )
24060 <returnvalue>boolean
</returnvalue>
24063 Tests whether an index column has the named property.
24064 Common index column properties are listed in
24065 <xref linkend=
"functions-info-index-column-props"/>.
24066 (Note that extension access methods can define additional property
24067 names for their indexes.)
24068 <literal>NULL
</literal> is returned if the property name is not known
24069 or does not apply to the particular object, or if the OID or column
24070 number does not identify a valid object.
24075 <entry role=
"func_table_entry"><para role=
"func_signature">
24077 <primary>pg_index_has_property
</primary>
24079 <function>pg_index_has_property
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>property
</parameter> <type>text
</type> )
24080 <returnvalue>boolean
</returnvalue>
24083 Tests whether an index has the named property.
24084 Common index properties are listed in
24085 <xref linkend=
"functions-info-index-props"/>.
24086 (Note that extension access methods can define additional property
24087 names for their indexes.)
24088 <literal>NULL
</literal> is returned if the property name is not known
24089 or does not apply to the particular object, or if the OID does not
24090 identify a valid object.
24095 <entry role=
"func_table_entry"><para role=
"func_signature">
24097 <primary>pg_indexam_has_property
</primary>
24099 <function>pg_indexam_has_property
</function> (
<parameter>am
</parameter> <type>oid
</type>,
<parameter>property
</parameter> <type>text
</type> )
24100 <returnvalue>boolean
</returnvalue>
24103 Tests whether an index access method has the named property.
24104 Access method properties are listed in
24105 <xref linkend=
"functions-info-indexam-props"/>.
24106 <literal>NULL
</literal> is returned if the property name is not known
24107 or does not apply to the particular object, or if the OID does not
24108 identify a valid object.
24113 <entry role=
"func_table_entry"><para role=
"func_signature">
24115 <primary>pg_options_to_table
</primary>
24117 <function>pg_options_to_table
</function> (
<parameter>options_array
</parameter> <type>text[]
</type> )
24118 <returnvalue>setof record
</returnvalue>
24119 (
<parameter>option_name
</parameter> <type>text
</type>,
24120 <parameter>option_value
</parameter> <type>text
</type> )
24123 Returns the set of storage options represented by a value from
24124 <structname>pg_class
</structname>.
<structfield>reloptions
</structfield> or
24125 <structname>pg_attribute
</structname>.
<structfield>attoptions
</structfield>.
24130 <entry role=
"func_table_entry"><para role=
"func_signature">
24132 <primary>pg_settings_get_flags
</primary>
24134 <function>pg_settings_get_flags
</function> (
<parameter>guc
</parameter> <type>text
</type> )
24135 <returnvalue>text[]
</returnvalue>
24138 Returns an array of the flags associated with the given GUC, or
24139 <literal>NULL
</literal> if it does not exist. The result is
24140 an empty array if the GUC exists but there are no flags to show.
24141 Only the most useful flags listed in
24142 <xref linkend=
"functions-pg-settings-flags"/> are exposed.
24147 <entry role=
"func_table_entry"><para role=
"func_signature">
24149 <primary>pg_tablespace_databases
</primary>
24151 <function>pg_tablespace_databases
</function> (
<parameter>tablespace
</parameter> <type>oid
</type> )
24152 <returnvalue>setof oid
</returnvalue>
24155 Returns the set of OIDs of databases that have objects stored in the
24156 specified tablespace. If this function returns any rows, the
24157 tablespace is not empty and cannot be dropped. To identify the specific
24158 objects populating the tablespace, you will need to connect to the
24159 database(s) identified by
<function>pg_tablespace_databases
</function>
24160 and query their
<structname>pg_class
</structname> catalogs.
24165 <entry role=
"func_table_entry"><para role=
"func_signature">
24167 <primary>pg_tablespace_location
</primary>
24169 <function>pg_tablespace_location
</function> (
<parameter>tablespace
</parameter> <type>oid
</type> )
24170 <returnvalue>text
</returnvalue>
24173 Returns the file system path that this tablespace is located in.
24178 <entry role=
"func_table_entry"><para role=
"func_signature">
24180 <primary>pg_typeof
</primary>
24182 <function>pg_typeof
</function> (
<type>"any"</type> )
24183 <returnvalue>regtype
</returnvalue>
24186 Returns the OID of the data type of the value that is passed to it.
24187 This can be helpful for troubleshooting or dynamically constructing
24188 SQL queries. The function is declared as
24189 returning
<type>regtype
</type>, which is an OID alias type (see
24190 <xref linkend=
"datatype-oid"/>); this means that it is the same as an
24191 OID for comparison purposes but displays as a type name.
24196 SELECT pg_typeof(
33);
24201 SELECT typlen FROM pg_type WHERE oid = pg_typeof(
33);
24210 <entry role=
"func_table_entry"><para role=
"func_signature">
24212 <primary>COLLATION FOR
</primary>
24214 <function>COLLATION FOR
</function> (
<type>"any"</type> )
24215 <returnvalue>text
</returnvalue>
24218 Returns the name of the collation of the value that is passed to it.
24219 The value is quoted and schema-qualified if necessary. If no
24220 collation was derived for the argument expression,
24221 then
<literal>NULL
</literal> is returned. If the argument is not of a
24222 collatable data type, then an error is raised.
24227 SELECT collation for (description) FROM pg_description LIMIT
1;
24232 SELECT collation for ('foo' COLLATE
"de_DE");
24241 <entry role=
"func_table_entry"><para role=
"func_signature">
24243 <primary>to_regclass
</primary>
24245 <function>to_regclass
</function> (
<type>text
</type> )
24246 <returnvalue>regclass
</returnvalue>
24249 Translates a textual relation name to its OID. A similar result is
24250 obtained by casting the string to type
<type>regclass
</type> (see
24251 <xref linkend=
"datatype-oid"/>); however, this function will return
24252 <literal>NULL
</literal> rather than throwing an error if the name is
24258 <entry role=
"func_table_entry"><para role=
"func_signature">
24260 <primary>to_regcollation
</primary>
24262 <function>to_regcollation
</function> (
<type>text
</type> )
24263 <returnvalue>regcollation
</returnvalue>
24266 Translates a textual collation name to its OID. A similar result is
24267 obtained by casting the string to type
<type>regcollation
</type> (see
24268 <xref linkend=
"datatype-oid"/>); however, this function will return
24269 <literal>NULL
</literal> rather than throwing an error if the name is
24275 <entry role=
"func_table_entry"><para role=
"func_signature">
24277 <primary>to_regnamespace
</primary>
24279 <function>to_regnamespace
</function> (
<type>text
</type> )
24280 <returnvalue>regnamespace
</returnvalue>
24283 Translates a textual schema name to its OID. A similar result is
24284 obtained by casting the string to type
<type>regnamespace
</type> (see
24285 <xref linkend=
"datatype-oid"/>); however, this function will return
24286 <literal>NULL
</literal> rather than throwing an error if the name is
24292 <entry role=
"func_table_entry"><para role=
"func_signature">
24294 <primary>to_regoper
</primary>
24296 <function>to_regoper
</function> (
<type>text
</type> )
24297 <returnvalue>regoper
</returnvalue>
24300 Translates a textual operator name to its OID. A similar result is
24301 obtained by casting the string to type
<type>regoper
</type> (see
24302 <xref linkend=
"datatype-oid"/>); however, this function will return
24303 <literal>NULL
</literal> rather than throwing an error if the name is
24304 not found or is ambiguous.
24309 <entry role=
"func_table_entry"><para role=
"func_signature">
24311 <primary>to_regoperator
</primary>
24313 <function>to_regoperator
</function> (
<type>text
</type> )
24314 <returnvalue>regoperator
</returnvalue>
24317 Translates a textual operator name (with parameter types) to its OID. A similar result is
24318 obtained by casting the string to type
<type>regoperator
</type> (see
24319 <xref linkend=
"datatype-oid"/>); however, this function will return
24320 <literal>NULL
</literal> rather than throwing an error if the name is
24326 <entry role=
"func_table_entry"><para role=
"func_signature">
24328 <primary>to_regproc
</primary>
24330 <function>to_regproc
</function> (
<type>text
</type> )
24331 <returnvalue>regproc
</returnvalue>
24334 Translates a textual function or procedure name to its OID. A similar result is
24335 obtained by casting the string to type
<type>regproc
</type> (see
24336 <xref linkend=
"datatype-oid"/>); however, this function will return
24337 <literal>NULL
</literal> rather than throwing an error if the name is
24338 not found or is ambiguous.
24343 <entry role=
"func_table_entry"><para role=
"func_signature">
24345 <primary>to_regprocedure
</primary>
24347 <function>to_regprocedure
</function> (
<type>text
</type> )
24348 <returnvalue>regprocedure
</returnvalue>
24351 Translates a textual function or procedure name (with argument types) to its OID. A similar result is
24352 obtained by casting the string to type
<type>regprocedure
</type> (see
24353 <xref linkend=
"datatype-oid"/>); however, this function will return
24354 <literal>NULL
</literal> rather than throwing an error if the name is
24360 <entry role=
"func_table_entry"><para role=
"func_signature">
24362 <primary>to_regrole
</primary>
24364 <function>to_regrole
</function> (
<type>text
</type> )
24365 <returnvalue>regrole
</returnvalue>
24368 Translates a textual role name to its OID. A similar result is
24369 obtained by casting the string to type
<type>regrole
</type> (see
24370 <xref linkend=
"datatype-oid"/>); however, this function will return
24371 <literal>NULL
</literal> rather than throwing an error if the name is
24377 <entry role=
"func_table_entry"><para role=
"func_signature">
24379 <primary>to_regtype
</primary>
24381 <function>to_regtype
</function> (
<type>text
</type> )
24382 <returnvalue>regtype
</returnvalue>
24385 Translates a textual type name to its OID. A similar result is
24386 obtained by casting the string to type
<type>regtype
</type> (see
24387 <xref linkend=
"datatype-oid"/>); however, this function will return
24388 <literal>NULL
</literal> rather than throwing an error if the name is
24397 Most of the functions that reconstruct (decompile) database objects
24398 have an optional
<parameter>pretty
</parameter> flag, which
24399 if
<literal>true
</literal> causes the result to
24400 be
<quote>pretty-printed
</quote>. Pretty-printing suppresses unnecessary
24401 parentheses and adds whitespace for legibility.
24402 The pretty-printed format is more readable, but the default format
24403 is more likely to be interpreted the same way by future versions of
24404 <productname>PostgreSQL
</productname>; so avoid using pretty-printed output
24405 for dump purposes. Passing
<literal>false
</literal> for
24406 the
<parameter>pretty
</parameter> parameter yields the same result as
24407 omitting the parameter.
24410 <table id=
"functions-info-index-column-props">
24411 <title>Index Column Properties
</title>
24414 <row><entry>Name
</entry><entry>Description
</entry></row>
24418 <entry><literal>asc
</literal></entry>
24419 <entry>Does the column sort in ascending order on a forward scan?
24423 <entry><literal>desc
</literal></entry>
24424 <entry>Does the column sort in descending order on a forward scan?
24428 <entry><literal>nulls_first
</literal></entry>
24429 <entry>Does the column sort with nulls first on a forward scan?
24433 <entry><literal>nulls_last
</literal></entry>
24434 <entry>Does the column sort with nulls last on a forward scan?
24438 <entry><literal>orderable
</literal></entry>
24439 <entry>Does the column possess any defined sort ordering?
24443 <entry><literal>distance_orderable
</literal></entry>
24444 <entry>Can the column be scanned in order by a
<quote>distance
</quote>
24445 operator, for example
<literal>ORDER BY col
<-
> constant
</literal> ?
24449 <entry><literal>returnable
</literal></entry>
24450 <entry>Can the column value be returned by an index-only scan?
24454 <entry><literal>search_array
</literal></entry>
24455 <entry>Does the column natively support
<literal>col = ANY(array)
</literal>
24460 <entry><literal>search_nulls
</literal></entry>
24461 <entry>Does the column support
<literal>IS NULL
</literal> and
24462 <literal>IS NOT NULL
</literal> searches?
24469 <table id=
"functions-info-index-props">
24470 <title>Index Properties
</title>
24473 <row><entry>Name
</entry><entry>Description
</entry></row>
24477 <entry><literal>clusterable
</literal></entry>
24478 <entry>Can the index be used in a
<literal>CLUSTER
</literal> command?
24482 <entry><literal>index_scan
</literal></entry>
24483 <entry>Does the index support plain (non-bitmap) scans?
24487 <entry><literal>bitmap_scan
</literal></entry>
24488 <entry>Does the index support bitmap scans?
24492 <entry><literal>backward_scan
</literal></entry>
24493 <entry>Can the scan direction be changed in mid-scan (to
24494 support
<literal>FETCH BACKWARD
</literal> on a cursor without
24495 needing materialization)?
24502 <table id=
"functions-info-indexam-props">
24503 <title>Index Access Method Properties
</title>
24506 <row><entry>Name
</entry><entry>Description
</entry></row>
24510 <entry><literal>can_order
</literal></entry>
24511 <entry>Does the access method support
<literal>ASC
</literal>,
24512 <literal>DESC
</literal> and related keywords in
24513 <literal>CREATE INDEX
</literal>?
24517 <entry><literal>can_unique
</literal></entry>
24518 <entry>Does the access method support unique indexes?
24522 <entry><literal>can_multi_col
</literal></entry>
24523 <entry>Does the access method support indexes with multiple columns?
24527 <entry><literal>can_exclude
</literal></entry>
24528 <entry>Does the access method support exclusion constraints?
24532 <entry><literal>can_include
</literal></entry>
24533 <entry>Does the access method support the
<literal>INCLUDE
</literal>
24534 clause of
<literal>CREATE INDEX
</literal>?
24541 <table id=
"functions-pg-settings-flags">
24542 <title>GUC Flags
</title>
24545 <row><entry>Flag
</entry><entry>Description
</entry></row>
24549 <entry><literal>EXPLAIN
</literal></entry>
24550 <entry>Parameters with this flag are included in
24551 <command>EXPLAIN (SETTINGS)
</command> commands.
24555 <entry><literal>NO_SHOW_ALL
</literal></entry>
24556 <entry>Parameters with this flag are excluded from
24557 <command>SHOW ALL
</command> commands.
24561 <entry><literal>NO_RESET
</literal></entry>
24562 <entry>Parameters with this flag do not support
24563 <command>RESET
</command> commands.
24567 <entry><literal>NO_RESET_ALL
</literal></entry>
24568 <entry>Parameters with this flag are excluded from
24569 <command>RESET ALL
</command> commands.
24573 <entry><literal>NOT_IN_SAMPLE
</literal></entry>
24574 <entry>Parameters with this flag are not included in
24575 <filename>postgresql.conf
</filename> by default.
24579 <entry><literal>RUNTIME_COMPUTED
</literal></entry>
24580 <entry>Parameters with this flag are runtime-computed ones.
24589 <sect2 id=
"functions-info-object">
24590 <title>Object Information and Addressing Functions
</title>
24593 <xref linkend=
"functions-info-object-table"/> lists functions related to
24594 database object identification and addressing.
24597 <table id=
"functions-info-object-table">
24598 <title>Object Information and Addressing Functions
</title>
24602 <entry role=
"func_table_entry"><para role=
"func_signature">
24613 <entry role=
"func_table_entry"><para role=
"func_signature">
24615 <primary>pg_describe_object
</primary>
24617 <function>pg_describe_object
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
24618 <returnvalue>text
</returnvalue>
24621 Returns a textual description of a database object identified by
24622 catalog OID, object OID, and sub-object ID (such as a column number
24623 within a table; the sub-object ID is zero when referring to a whole
24624 object). This description is intended to be human-readable, and might
24625 be translated, depending on server configuration. This is especially
24626 useful to determine the identity of an object referenced in the
24627 <structname>pg_depend
</structname> catalog. This function returns
24628 <literal>NULL
</literal> values for undefined objects.
24633 <entry role=
"func_table_entry"><para role=
"func_signature">
24635 <primary>pg_identify_object
</primary>
24637 <function>pg_identify_object
</function> (
<parameter>classid
</parameter> <type>oid
</type>,
<parameter>objid
</parameter> <type>oid
</type>,
<parameter>objsubid
</parameter> <type>integer
</type> )
24638 <returnvalue>record
</returnvalue>
24639 (
<parameter>type
</parameter> <type>text
</type>,
24640 <parameter>schema
</parameter> <type>text
</type>,
24641 <parameter>name
</parameter> <type>text
</type>,
24642 <parameter>identity
</parameter> <type>text
</type> )
24645 Returns a row containing enough information to uniquely identify the
24646 database object specified by catalog OID, object OID and sub-object
24648 This information is intended to be machine-readable, and is never
24650 <parameter>type
</parameter> identifies the type of database object;
24651 <parameter>schema
</parameter> is the schema name that the object
24652 belongs in, or
<literal>NULL
</literal> for object types that do not
24654 <parameter>name
</parameter> is the name of the object, quoted if
24655 necessary, if the name (along with schema name, if pertinent) is
24656 sufficient to uniquely identify the object,
24657 otherwise
<literal>NULL
</literal>;
24658 <parameter>identity
</parameter> is the complete object identity, with
24659 the precise format depending on object type, and each name within the
24660 format being schema-qualified and quoted as necessary. Undefined
24661 objects are identified with
<literal>NULL
</literal> values.
24666 <entry role=
"func_table_entry"><para role=
"func_signature">
24668 <primary>pg_identify_object_as_address
</primary>
24670 <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> )
24671 <returnvalue>record
</returnvalue>
24672 (
<parameter>type
</parameter> <type>text
</type>,
24673 <parameter>object_names
</parameter> <type>text[]
</type>,
24674 <parameter>object_args
</parameter> <type>text[]
</type> )
24677 Returns a row containing enough information to uniquely identify the
24678 database object specified by catalog OID, object OID and sub-object
24680 The returned information is independent of the current server, that
24681 is, it could be used to identify an identically named object in
24683 <parameter>type
</parameter> identifies the type of database object;
24684 <parameter>object_names
</parameter> and
24685 <parameter>object_args
</parameter>
24686 are text arrays that together form a reference to the object.
24687 These three values can be passed
24688 to
<function>pg_get_object_address
</function> to obtain the internal
24689 address of the object.
24694 <entry role=
"func_table_entry"><para role=
"func_signature">
24696 <primary>pg_get_object_address
</primary>
24698 <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> )
24699 <returnvalue>record
</returnvalue>
24700 (
<parameter>classid
</parameter> <type>oid
</type>,
24701 <parameter>objid
</parameter> <type>oid
</type>,
24702 <parameter>objsubid
</parameter> <type>integer
</type> )
24705 Returns a row containing enough information to uniquely identify the
24706 database object specified by a type code and object name and argument
24708 The returned values are the ones that would be used in system catalogs
24709 such as
<structname>pg_depend
</structname>; they can be passed to
24710 other system functions such as
<function>pg_describe_object
</function>
24711 or
<function>pg_identify_object
</function>.
24712 <parameter>classid
</parameter> is the OID of the system catalog
24713 containing the object;
24714 <parameter>objid
</parameter> is the OID of the object itself, and
24715 <parameter>objsubid
</parameter> is the sub-object ID, or zero if none.
24716 This function is the inverse
24717 of
<function>pg_identify_object_as_address
</function>.
24718 Undefined objects are identified with
<literal>NULL
</literal> values.
24727 <sect2 id=
"functions-info-comment">
24728 <title>Comment Information Functions
</title>
24731 <primary>comment
</primary>
24732 <secondary sortas=
"database objects">about database objects
</secondary>
24736 The functions shown in
<xref linkend=
"functions-info-comment-table"/>
24737 extract comments previously stored with the
<xref linkend=
"sql-comment"/>
24738 command. A null value is returned if no
24739 comment could be found for the specified parameters.
24742 <table id=
"functions-info-comment-table">
24743 <title>Comment Information Functions
</title>
24747 <entry role=
"func_table_entry"><para role=
"func_signature">
24758 <entry role=
"func_table_entry"><para role=
"func_signature">
24760 <primary>col_description
</primary>
24762 <function>col_description
</function> (
<parameter>table
</parameter> <type>oid
</type>,
<parameter>column
</parameter> <type>integer
</type> )
24763 <returnvalue>text
</returnvalue>
24766 Returns the comment for a table column, which is specified by the OID
24767 of its table and its column number.
24768 (
<function>obj_description
</function> cannot be used for table
24769 columns, since columns do not have OIDs of their own.)
24774 <entry role=
"func_table_entry"><para role=
"func_signature">
24776 <primary>obj_description
</primary>
24778 <function>obj_description
</function> (
<parameter>object
</parameter> <type>oid
</type>,
<parameter>catalog
</parameter> <type>name
</type> )
24779 <returnvalue>text
</returnvalue>
24782 Returns the comment for a database object specified by its OID and the
24783 name of the containing system catalog. For
24784 example,
<literal>obj_description(
123456, 'pg_class')
</literal> would
24785 retrieve the comment for the table with OID
123456.
24790 <entry role=
"func_table_entry"><para role=
"func_signature">
24791 <function>obj_description
</function> (
<parameter>object
</parameter> <type>oid
</type> )
24792 <returnvalue>text
</returnvalue>
24795 Returns the comment for a database object specified by its OID alone.
24796 This is
<emphasis>deprecated
</emphasis> since there is no guarantee
24797 that OIDs are unique across different system catalogs; therefore, the
24798 wrong comment might be returned.
24803 <entry role=
"func_table_entry"><para role=
"func_signature">
24805 <primary>shobj_description
</primary>
24807 <function>shobj_description
</function> (
<parameter>object
</parameter> <type>oid
</type>,
<parameter>catalog
</parameter> <type>name
</type> )
24808 <returnvalue>text
</returnvalue>
24811 Returns the comment for a shared database object specified by its OID
24812 and the name of the containing system catalog. This is just
24813 like
<function>obj_description
</function> except that it is used for
24814 retrieving comments on shared objects (that is, databases, roles, and
24815 tablespaces). Some system catalogs are global to all databases within
24816 each cluster, and the descriptions for objects in them are stored
24826 <sect2 id=
"functions-info-validity">
24827 <title>Data Validity Checking Functions
</title>
24830 The functions shown in
<xref linkend=
"functions-info-validity-table"/>
24831 can be helpful for checking validity of proposed input data.
24834 <table id=
"functions-info-validity-table">
24835 <title>Data Validity Checking Functions
</title>
24839 <entry role=
"func_table_entry"><para role=
"func_signature">
24853 <entry role=
"func_table_entry"><para role=
"func_signature">
24855 <primary>pg_input_is_valid
</primary>
24857 <function>pg_input_is_valid
</function> (
24858 <parameter>string
</parameter> <type>text
</type>,
24859 <parameter>type
</parameter> <type>text
</type>
24861 <returnvalue>boolean
</returnvalue>
24864 Tests whether the given
<parameter>string
</parameter> is valid
24865 input for the specified data type, returning true or false.
24868 This function will only work as desired if the data type's input
24869 function has been updated to report invalid input as
24870 a
<quote>soft
</quote> error. Otherwise, invalid input will abort
24871 the transaction, just as if the string had been cast to the type
24875 <literal>pg_input_is_valid('
42', 'integer')
</literal>
24876 <returnvalue>t
</returnvalue>
24879 <literal>pg_input_is_valid('
42000000000', 'integer')
</literal>
24880 <returnvalue>f
</returnvalue>
24883 <literal>pg_input_is_valid('
1234.567', 'numeric(
7,
4)')
</literal>
24884 <returnvalue>f
</returnvalue>
24888 <entry role=
"func_table_entry"><para role=
"func_signature">
24890 <primary>pg_input_error_info
</primary>
24892 <function>pg_input_error_info
</function> (
24893 <parameter>string
</parameter> <type>text
</type>,
24894 <parameter>type
</parameter> <type>text
</type>
24896 <returnvalue>record
</returnvalue>
24897 (
<parameter>message
</parameter> <type>text
</type>,
24898 <parameter>detail
</parameter> <type>text
</type>,
24899 <parameter>hint
</parameter> <type>text
</type>,
24900 <parameter>sql_error_code
</parameter> <type>text
</type> )
24903 Tests whether the given
<parameter>string
</parameter> is valid
24904 input for the specified data type; if not, return the details of
24905 the error would have been thrown. If the input is valid, the
24906 results are NULL. The inputs are the same as
24907 for
<function>pg_input_is_valid
</function>.
24910 This function will only work as desired if the data type's input
24911 function has been updated to report invalid input as
24912 a
<quote>soft
</quote> error. Otherwise, invalid input will abort
24913 the transaction, just as if the string had been cast to the type
24918 SELECT * FROM pg_input_error_info('
42000000000', 'integer');
24919 message | detail | hint | sql_error_code
24920 ------------------------------------------------------+--------+------+----------------
24921 value
"42000000000" is out of range for type integer | | |
22003
24923 SELECT * FROM pg_input_error_info('
1234.567', 'numeric(
7,
4)');
24924 message | detail | hint | sql_error_code
24925 ------------------------+-----------------------------------------------------------------------------------+------+----------------
24926 numeric field overflow | A field with precision
7, scale
4 must round to an absolute value less than
10^
3. | |
22003
24936 <sect2 id=
"functions-info-snapshot">
24937 <title>Transaction ID and Snapshot Information Functions
</title>
24940 The functions shown in
<xref linkend=
"functions-pg-snapshot"/>
24941 provide server transaction information in an exportable form. The main
24942 use of these functions is to determine which transactions were committed
24943 between two snapshots.
24946 <table id=
"functions-pg-snapshot">
24947 <title>Transaction ID and Snapshot Information Functions
</title>
24951 <entry role=
"func_table_entry"><para role=
"func_signature">
24962 <entry role=
"func_table_entry"><para role=
"func_signature">
24964 <primary>pg_current_xact_id
</primary>
24966 <function>pg_current_xact_id
</function> ()
24967 <returnvalue>xid8
</returnvalue>
24970 Returns the current transaction's ID. It will assign a new one if the
24971 current transaction does not have one already (because it has not
24972 performed any database updates); see
<xref
24973 linkend=
"transaction-id"/> for details. If executed in a
24974 subtransaction, this will return the top-level transaction ID;
24975 see
<xref linkend=
"subxacts"/> for details.
24980 <entry role=
"func_table_entry"><para role=
"func_signature">
24982 <primary>pg_current_xact_id_if_assigned
</primary>
24984 <function>pg_current_xact_id_if_assigned
</function> ()
24985 <returnvalue>xid8
</returnvalue>
24988 Returns the current transaction's ID, or
<literal>NULL
</literal> if no
24989 ID is assigned yet. (It's best to use this variant if the transaction
24990 might otherwise be read-only, to avoid unnecessary consumption of an
24992 If executed in a subtransaction, this will return the top-level
24998 <entry role=
"func_table_entry"><para role=
"func_signature">
25000 <primary>pg_xact_status
</primary>
25002 <function>pg_xact_status
</function> (
<type>xid8
</type> )
25003 <returnvalue>text
</returnvalue>
25006 Reports the commit status of a recent transaction.
25007 The result is one of
<literal>in progress
</literal>,
25008 <literal>committed
</literal>, or
<literal>aborted
</literal>,
25009 provided that the transaction is recent enough that the system retains
25010 the commit status of that transaction.
25011 If it is old enough that no references to the transaction survive in
25012 the system and the commit status information has been discarded, the
25013 result is
<literal>NULL
</literal>.
25014 Applications might use this function, for example, to determine
25015 whether their transaction committed or aborted after the application
25016 and database server become disconnected while
25017 a
<literal>COMMIT
</literal> is in progress.
25018 Note that prepared transactions are reported as
<literal>in
25019 progress
</literal>; applications must check
<link
25020 linkend=
"view-pg-prepared-xacts"><structname>pg_prepared_xacts
</structname></link>
25021 if they need to determine whether a transaction ID belongs to a
25022 prepared transaction.
25027 <entry role=
"func_table_entry"><para role=
"func_signature">
25029 <primary>pg_current_snapshot
</primary>
25031 <function>pg_current_snapshot
</function> ()
25032 <returnvalue>pg_snapshot
</returnvalue>
25035 Returns a current
<firstterm>snapshot
</firstterm>, a data structure
25036 showing which transaction IDs are now in-progress.
25037 Only top-level transaction IDs are included in the snapshot;
25038 subtransaction IDs are not shown; see
<xref linkend=
"subxacts"/>
25044 <entry role=
"func_table_entry"><para role=
"func_signature">
25046 <primary>pg_snapshot_xip
</primary>
25048 <function>pg_snapshot_xip
</function> (
<type>pg_snapshot
</type> )
25049 <returnvalue>setof xid8
</returnvalue>
25052 Returns the set of in-progress transaction IDs contained in a snapshot.
25057 <entry role=
"func_table_entry"><para role=
"func_signature">
25059 <primary>pg_snapshot_xmax
</primary>
25061 <function>pg_snapshot_xmax
</function> (
<type>pg_snapshot
</type> )
25062 <returnvalue>xid8
</returnvalue>
25065 Returns the
<structfield>xmax
</structfield> of a snapshot.
25070 <entry role=
"func_table_entry"><para role=
"func_signature">
25072 <primary>pg_snapshot_xmin
</primary>
25074 <function>pg_snapshot_xmin
</function> (
<type>pg_snapshot
</type> )
25075 <returnvalue>xid8
</returnvalue>
25078 Returns the
<structfield>xmin
</structfield> of a snapshot.
25083 <entry role=
"func_table_entry"><para role=
"func_signature">
25085 <primary>pg_visible_in_snapshot
</primary>
25087 <function>pg_visible_in_snapshot
</function> (
<type>xid8
</type>,
<type>pg_snapshot
</type> )
25088 <returnvalue>boolean
</returnvalue>
25091 Is the given transaction ID
<firstterm>visible
</firstterm> according
25092 to this snapshot (that is, was it completed before the snapshot was
25093 taken)? Note that this function will not give the correct answer for
25094 a subtransaction ID (subxid); see
<xref linkend=
"subxacts"/> for
25103 The internal transaction ID type
<type>xid
</type> is
32 bits wide and
25104 wraps around every
4 billion transactions. However,
25105 the functions shown in
<xref linkend=
"functions-pg-snapshot"/> use a
25106 64-bit type
<type>xid8
</type> that does not wrap around during the life
25107 of an installation and can be converted to
<type>xid
</type> by casting if
25108 required; see
<xref linkend=
"transaction-id"/> for details.
25109 The data type
<type>pg_snapshot
</type> stores information about
25110 transaction ID visibility at a particular moment in time. Its components
25111 are described in
<xref linkend=
"functions-pg-snapshot-parts"/>.
25112 <type>pg_snapshot
</type>'s textual representation is
25113 <literal><replaceable>xmin
</replaceable>:
<replaceable>xmax
</replaceable>:
<replaceable>xip_list
</replaceable></literal>.
25114 For example
<literal>10:
20:
10,
14,
15</literal> means
25115 <literal>xmin=
10, xmax=
20, xip_list=
10,
14,
15</literal>.
25118 <table id=
"functions-pg-snapshot-parts">
25119 <title>Snapshot Components
</title>
25123 <entry>Name
</entry>
25124 <entry>Description
</entry>
25130 <entry><structfield>xmin
</structfield></entry>
25132 Lowest transaction ID that was still active. All transaction IDs
25133 less than
<structfield>xmin
</structfield> are either committed and visible,
25134 or rolled back and dead.
25139 <entry><structfield>xmax
</structfield></entry>
25141 One past the highest completed transaction ID. All transaction IDs
25142 greater than or equal to
<structfield>xmax
</structfield> had not yet
25143 completed as of the time of the snapshot, and thus are invisible.
25148 <entry><structfield>xip_list
</structfield></entry>
25150 Transactions in progress at the time of the snapshot. A transaction
25151 ID that is
<literal>xmin
<=
<replaceable>X
</replaceable> <
25152 xmax
</literal> and not in this list was already completed at the time
25153 of the snapshot, and thus is either visible or dead according to its
25154 commit status. This list does not include the transaction IDs of
25155 subtransactions (subxids).
25163 In releases of
<productname>PostgreSQL
</productname> before
13 there was
25164 no
<type>xid8
</type> type, so variants of these functions were provided
25165 that used
<type>bigint
</type> to represent a
64-bit XID, with a
25166 correspondingly distinct snapshot data type
<type>txid_snapshot
</type>.
25167 These older functions have
<literal>txid
</literal> in their names. They
25168 are still supported for backward compatibility, but may be removed from a
25169 future release. See
<xref linkend=
"functions-txid-snapshot"/>.
25172 <table id=
"functions-txid-snapshot">
25173 <title>Deprecated Transaction ID and Snapshot Information Functions
</title>
25177 <entry role=
"func_table_entry"><para role=
"func_signature">
25188 <entry role=
"func_table_entry"><para role=
"func_signature">
25190 <primary>txid_current
</primary>
25192 <function>txid_current
</function> ()
25193 <returnvalue>bigint
</returnvalue>
25196 See
<function>pg_current_xact_id()
</function>.
25201 <entry role=
"func_table_entry"><para role=
"func_signature">
25203 <primary>txid_current_if_assigned
</primary>
25205 <function>txid_current_if_assigned
</function> ()
25206 <returnvalue>bigint
</returnvalue>
25209 See
<function>pg_current_xact_id_if_assigned()
</function>.
25214 <entry role=
"func_table_entry"><para role=
"func_signature">
25216 <primary>txid_current_snapshot
</primary>
25218 <function>txid_current_snapshot
</function> ()
25219 <returnvalue>txid_snapshot
</returnvalue>
25222 See
<function>pg_current_snapshot()
</function>.
25227 <entry role=
"func_table_entry"><para role=
"func_signature">
25229 <primary>txid_snapshot_xip
</primary>
25231 <function>txid_snapshot_xip
</function> (
<type>txid_snapshot
</type> )
25232 <returnvalue>setof bigint
</returnvalue>
25235 See
<function>pg_snapshot_xip()
</function>.
25240 <entry role=
"func_table_entry"><para role=
"func_signature">
25242 <primary>txid_snapshot_xmax
</primary>
25244 <function>txid_snapshot_xmax
</function> (
<type>txid_snapshot
</type> )
25245 <returnvalue>bigint
</returnvalue>
25248 See
<function>pg_snapshot_xmax()
</function>.
25253 <entry role=
"func_table_entry"><para role=
"func_signature">
25255 <primary>txid_snapshot_xmin
</primary>
25257 <function>txid_snapshot_xmin
</function> (
<type>txid_snapshot
</type> )
25258 <returnvalue>bigint
</returnvalue>
25261 See
<function>pg_snapshot_xmin()
</function>.
25266 <entry role=
"func_table_entry"><para role=
"func_signature">
25268 <primary>txid_visible_in_snapshot
</primary>
25270 <function>txid_visible_in_snapshot
</function> (
<type>bigint
</type>,
<type>txid_snapshot
</type> )
25271 <returnvalue>boolean
</returnvalue>
25274 See
<function>pg_visible_in_snapshot()
</function>.
25279 <entry role=
"func_table_entry"><para role=
"func_signature">
25281 <primary>txid_status
</primary>
25283 <function>txid_status
</function> (
<type>bigint
</type> )
25284 <returnvalue>text
</returnvalue>
25287 See
<function>pg_xact_status()
</function>.
25296 <sect2 id=
"functions-info-commit-timestamp">
25297 <title>Committed Transaction Information Functions
</title>
25300 The functions shown in
<xref linkend=
"functions-commit-timestamp"/>
25301 provide information about when past transactions were committed.
25302 They only provide useful data when the
25303 <xref linkend=
"guc-track-commit-timestamp"/> configuration option is
25304 enabled, and only for transactions that were committed after it was
25308 <table id=
"functions-commit-timestamp">
25309 <title>Committed Transaction Information Functions
</title>
25313 <entry role=
"func_table_entry"><para role=
"func_signature">
25324 <entry role=
"func_table_entry"><para role=
"func_signature">
25326 <primary>pg_xact_commit_timestamp
</primary>
25328 <function>pg_xact_commit_timestamp
</function> (
<type>xid
</type> )
25329 <returnvalue>timestamp with time zone
</returnvalue>
25332 Returns the commit timestamp of a transaction.
25337 <entry role=
"func_table_entry"><para role=
"func_signature">
25339 <primary>pg_xact_commit_timestamp_origin
</primary>
25341 <function>pg_xact_commit_timestamp_origin
</function> (
<type>xid
</type> )
25342 <returnvalue>record
</returnvalue>
25343 (
<parameter>timestamp
</parameter> <type>timestamp with time zone
</type>,
25344 <parameter>roident
</parameter> <type>oid
</type>)
25347 Returns the commit timestamp and replication origin of a transaction.
25352 <entry role=
"func_table_entry"><para role=
"func_signature">
25354 <primary>pg_last_committed_xact
</primary>
25356 <function>pg_last_committed_xact
</function> ()
25357 <returnvalue>record
</returnvalue>
25358 (
<parameter>xid
</parameter> <type>xid
</type>,
25359 <parameter>timestamp
</parameter> <type>timestamp with time zone
</type>,
25360 <parameter>roident
</parameter> <type>oid
</type> )
25363 Returns the transaction ID, commit timestamp and replication origin
25364 of the latest committed transaction.
25373 <sect2 id=
"functions-info-controldata">
25374 <title>Control Data Functions
</title>
25377 The functions shown in
<xref linkend=
"functions-controldata"/>
25378 print information initialized during
<command>initdb
</command>, such
25379 as the catalog version. They also show information about write-ahead
25380 logging and checkpoint processing. This information is cluster-wide,
25381 not specific to any one database. These functions provide most of the same
25382 information, from the same source, as the
25383 <xref linkend=
"app-pgcontroldata"/> application.
25386 <table id=
"functions-controldata">
25387 <title>Control Data Functions
</title>
25391 <entry role=
"func_table_entry"><para role=
"func_signature">
25402 <entry role=
"func_table_entry"><para role=
"func_signature">
25404 <primary>pg_control_checkpoint
</primary>
25406 <function>pg_control_checkpoint
</function> ()
25407 <returnvalue>record
</returnvalue>
25410 Returns information about current checkpoint state, as shown in
25411 <xref linkend=
"functions-pg-control-checkpoint"/>.
25416 <entry role=
"func_table_entry"><para role=
"func_signature">
25418 <primary>pg_control_system
</primary>
25420 <function>pg_control_system
</function> ()
25421 <returnvalue>record
</returnvalue>
25424 Returns information about current control file state, as shown in
25425 <xref linkend=
"functions-pg-control-system"/>.
25430 <entry role=
"func_table_entry"><para role=
"func_signature">
25432 <primary>pg_control_init
</primary>
25434 <function>pg_control_init
</function> ()
25435 <returnvalue>record
</returnvalue>
25438 Returns information about cluster initialization state, as shown in
25439 <xref linkend=
"functions-pg-control-init"/>.
25444 <entry role=
"func_table_entry"><para role=
"func_signature">
25446 <primary>pg_control_recovery
</primary>
25448 <function>pg_control_recovery
</function> ()
25449 <returnvalue>record
</returnvalue>
25452 Returns information about recovery state, as shown in
25453 <xref linkend=
"functions-pg-control-recovery"/>.
25460 <table id=
"functions-pg-control-checkpoint">
25461 <title><function>pg_control_checkpoint
</function> Output Columns
</title>
25465 <entry>Column Name
</entry>
25466 <entry>Data Type
</entry>
25473 <entry><structfield>checkpoint_lsn
</structfield></entry>
25474 <entry><type>pg_lsn
</type></entry>
25478 <entry><structfield>redo_lsn
</structfield></entry>
25479 <entry><type>pg_lsn
</type></entry>
25483 <entry><structfield>redo_wal_file
</structfield></entry>
25484 <entry><type>text
</type></entry>
25488 <entry><structfield>timeline_id
</structfield></entry>
25489 <entry><type>integer
</type></entry>
25493 <entry><structfield>prev_timeline_id
</structfield></entry>
25494 <entry><type>integer
</type></entry>
25498 <entry><structfield>full_page_writes
</structfield></entry>
25499 <entry><type>boolean
</type></entry>
25503 <entry><structfield>next_xid
</structfield></entry>
25504 <entry><type>text
</type></entry>
25508 <entry><structfield>next_oid
</structfield></entry>
25509 <entry><type>oid
</type></entry>
25513 <entry><structfield>next_multixact_id
</structfield></entry>
25514 <entry><type>xid
</type></entry>
25518 <entry><structfield>next_multi_offset
</structfield></entry>
25519 <entry><type>xid
</type></entry>
25523 <entry><structfield>oldest_xid
</structfield></entry>
25524 <entry><type>xid
</type></entry>
25528 <entry><structfield>oldest_xid_dbid
</structfield></entry>
25529 <entry><type>oid
</type></entry>
25533 <entry><structfield>oldest_active_xid
</structfield></entry>
25534 <entry><type>xid
</type></entry>
25538 <entry><structfield>oldest_multi_xid
</structfield></entry>
25539 <entry><type>xid
</type></entry>
25543 <entry><structfield>oldest_multi_dbid
</structfield></entry>
25544 <entry><type>oid
</type></entry>
25548 <entry><structfield>oldest_commit_ts_xid
</structfield></entry>
25549 <entry><type>xid
</type></entry>
25553 <entry><structfield>newest_commit_ts_xid
</structfield></entry>
25554 <entry><type>xid
</type></entry>
25558 <entry><structfield>checkpoint_time
</structfield></entry>
25559 <entry><type>timestamp with time zone
</type></entry>
25566 <table id=
"functions-pg-control-system">
25567 <title><function>pg_control_system
</function> Output Columns
</title>
25571 <entry>Column Name
</entry>
25572 <entry>Data Type
</entry>
25579 <entry><structfield>pg_control_version
</structfield></entry>
25580 <entry><type>integer
</type></entry>
25584 <entry><structfield>catalog_version_no
</structfield></entry>
25585 <entry><type>integer
</type></entry>
25589 <entry><structfield>system_identifier
</structfield></entry>
25590 <entry><type>bigint
</type></entry>
25594 <entry><structfield>pg_control_last_modified
</structfield></entry>
25595 <entry><type>timestamp with time zone
</type></entry>
25602 <table id=
"functions-pg-control-init">
25603 <title><function>pg_control_init
</function> Output Columns
</title>
25607 <entry>Column Name
</entry>
25608 <entry>Data Type
</entry>
25615 <entry><structfield>max_data_alignment
</structfield></entry>
25616 <entry><type>integer
</type></entry>
25620 <entry><structfield>database_block_size
</structfield></entry>
25621 <entry><type>integer
</type></entry>
25625 <entry><structfield>blocks_per_segment
</structfield></entry>
25626 <entry><type>integer
</type></entry>
25630 <entry><structfield>wal_block_size
</structfield></entry>
25631 <entry><type>integer
</type></entry>
25635 <entry><structfield>bytes_per_wal_segment
</structfield></entry>
25636 <entry><type>integer
</type></entry>
25640 <entry><structfield>max_identifier_length
</structfield></entry>
25641 <entry><type>integer
</type></entry>
25645 <entry><structfield>max_index_columns
</structfield></entry>
25646 <entry><type>integer
</type></entry>
25650 <entry><structfield>max_toast_chunk_size
</structfield></entry>
25651 <entry><type>integer
</type></entry>
25655 <entry><structfield>large_object_chunk_size
</structfield></entry>
25656 <entry><type>integer
</type></entry>
25660 <entry><structfield>float8_pass_by_value
</structfield></entry>
25661 <entry><type>boolean
</type></entry>
25665 <entry><structfield>data_page_checksum_version
</structfield></entry>
25666 <entry><type>integer
</type></entry>
25673 <table id=
"functions-pg-control-recovery">
25674 <title><function>pg_control_recovery
</function> Output Columns
</title>
25678 <entry>Column Name
</entry>
25679 <entry>Data Type
</entry>
25686 <entry><structfield>min_recovery_end_lsn
</structfield></entry>
25687 <entry><type>pg_lsn
</type></entry>
25691 <entry><structfield>min_recovery_end_timeline
</structfield></entry>
25692 <entry><type>integer
</type></entry>
25696 <entry><structfield>backup_start_lsn
</structfield></entry>
25697 <entry><type>pg_lsn
</type></entry>
25701 <entry><structfield>backup_end_lsn
</structfield></entry>
25702 <entry><type>pg_lsn
</type></entry>
25706 <entry><structfield>end_of_backup_record_required
</structfield></entry>
25707 <entry><type>boolean
</type></entry>
25718 <sect1 id=
"functions-admin">
25719 <title>System Administration Functions
</title>
25722 The functions described in this section are used to control and
25723 monitor a
<productname>PostgreSQL
</productname> installation.
25726 <sect2 id=
"functions-admin-set">
25727 <title>Configuration Settings Functions
</title>
25730 <primary>SET
</primary>
25734 <primary>SHOW
</primary>
25738 <primary>configuration
</primary>
25739 <secondary sortas=
"server">of the server
</secondary>
25740 <tertiary>functions
</tertiary>
25744 <xref linkend=
"functions-admin-set-table"/> shows the functions
25745 available to query and alter run-time configuration parameters.
25748 <table id=
"functions-admin-set-table">
25749 <title>Configuration Settings Functions
</title>
25753 <entry role=
"func_table_entry"><para role=
"func_signature">
25767 <entry role=
"func_table_entry"><para role=
"func_signature">
25769 <primary>current_setting
</primary>
25771 <function>current_setting
</function> (
<parameter>setting_name
</parameter> <type>text
</type> <optional>,
<parameter>missing_ok
</parameter> <type>boolean
</type> </optional> )
25772 <returnvalue>text
</returnvalue>
25775 Returns the current value of the
25776 setting
<parameter>setting_name
</parameter>. If there is no such
25777 setting,
<function>current_setting
</function> throws an error
25778 unless
<parameter>missing_ok
</parameter> is supplied and
25779 is
<literal>true
</literal> (in which case NULL is returned).
25780 This function corresponds to
25781 the
<acronym>SQL
</acronym> command
<xref linkend=
"sql-show"/>.
25784 <literal>current_setting('datestyle')
</literal>
25785 <returnvalue>ISO, MDY
</returnvalue>
25790 <entry role=
"func_table_entry"><para role=
"func_signature">
25792 <primary>set_config
</primary>
25794 <function>set_config
</function> (
25795 <parameter>setting_name
</parameter> <type>text
</type>,
25796 <parameter>new_value
</parameter> <type>text
</type>,
25797 <parameter>is_local
</parameter> <type>boolean
</type> )
25798 <returnvalue>text
</returnvalue>
25801 Sets the parameter
<parameter>setting_name
</parameter>
25802 to
<parameter>new_value
</parameter>, and returns that value.
25803 If
<parameter>is_local
</parameter> is
<literal>true
</literal>, the new
25804 value will only apply during the current transaction. If you want the
25805 new value to apply for the rest of the current session,
25806 use
<literal>false
</literal> instead. This function corresponds to
25807 the SQL command
<xref linkend=
"sql-set"/>.
25810 <literal>set_config('log_statement_stats', 'off', false)
</literal>
25811 <returnvalue>off
</returnvalue>
25820 <sect2 id=
"functions-admin-signal">
25821 <title>Server Signaling Functions
</title>
25824 <primary>signal
</primary>
25825 <secondary sortas=
"backend">backend processes
</secondary>
25829 The functions shown in
<xref
25830 linkend=
"functions-admin-signal-table"/> send control signals to
25831 other server processes. Use of these functions is restricted to
25832 superusers by default but access may be granted to others using
25833 <command>GRANT
</command>, with noted exceptions.
25837 Each of these functions returns
<literal>true
</literal> if
25838 the signal was successfully sent and
<literal>false
</literal>
25839 if sending the signal failed.
25842 <table id=
"functions-admin-signal-table">
25843 <title>Server Signaling Functions
</title>
25847 <entry role=
"func_table_entry"><para role=
"func_signature">
25858 <entry role=
"func_table_entry"><para role=
"func_signature">
25860 <primary>pg_cancel_backend
</primary>
25862 <function>pg_cancel_backend
</function> (
<parameter>pid
</parameter> <type>integer
</type> )
25863 <returnvalue>boolean
</returnvalue>
25866 Cancels the current query of the session whose backend process has the
25867 specified process ID. This is also allowed if the
25868 calling role is a member of the role whose backend is being canceled or
25869 the calling role has privileges of
<literal>pg_signal_backend
</literal>,
25870 however only superusers can cancel superuser backends.
25875 <entry role=
"func_table_entry"><para role=
"func_signature">
25877 <primary>pg_log_backend_memory_contexts
</primary>
25879 <function>pg_log_backend_memory_contexts
</function> (
<parameter>pid
</parameter> <type>integer
</type> )
25880 <returnvalue>boolean
</returnvalue>
25883 Requests to log the memory contexts of the backend with the
25884 specified process ID. This function can send the request to
25885 backends and auxiliary processes except logger. These memory contexts
25887 <literal>LOG
</literal> message level. They will appear in
25888 the server log based on the log configuration set
25889 (see
<xref linkend=
"runtime-config-logging"/> for more information),
25890 but will not be sent to the client regardless of
25891 <xref linkend=
"guc-client-min-messages"/>.
25896 <entry role=
"func_table_entry"><para role=
"func_signature">
25898 <primary>pg_reload_conf
</primary>
25900 <function>pg_reload_conf
</function> ()
25901 <returnvalue>boolean
</returnvalue>
25904 Causes all processes of the
<productname>PostgreSQL
</productname>
25905 server to reload their configuration files. (This is initiated by
25906 sending a
<systemitem>SIGHUP
</systemitem> signal to the postmaster
25907 process, which in turn sends
<systemitem>SIGHUP
</systemitem> to each
25908 of its children.) You can use the
25909 <link linkend=
"view-pg-file-settings"><structname>pg_file_settings
</structname></link>,
25910 <link linkend=
"view-pg-hba-file-rules"><structname>pg_hba_file_rules
</structname></link> and
25911 <link linkend=
"view-pg-hba-file-rules"><structname>pg_ident_file_mappings
</structname></link> views
25912 to check the configuration files for possible errors, before reloading.
25917 <entry role=
"func_table_entry"><para role=
"func_signature">
25919 <primary>pg_rotate_logfile
</primary>
25921 <function>pg_rotate_logfile
</function> ()
25922 <returnvalue>boolean
</returnvalue>
25925 Signals the log-file manager to switch to a new output file
25926 immediately. This works only when the built-in log collector is
25927 running, since otherwise there is no log-file manager subprocess.
25932 <entry role=
"func_table_entry"><para role=
"func_signature">
25934 <primary>pg_terminate_backend
</primary>
25936 <function>pg_terminate_backend
</function> (
<parameter>pid
</parameter> <type>integer
</type>,
<parameter>timeout
</parameter> <type>bigint
</type> <literal>DEFAULT
</literal> <literal>0</literal> )
25937 <returnvalue>boolean
</returnvalue>
25940 Terminates the session whose backend process has the
25941 specified process ID. This is also allowed if the calling role
25942 is a member of the role whose backend is being terminated or the
25943 calling role has privileges of
<literal>pg_signal_backend
</literal>,
25944 however only superusers can terminate superuser backends.
25947 If
<parameter>timeout
</parameter> is not specified or zero, this
25948 function returns
<literal>true
</literal> whether the process actually
25949 terminates or not, indicating only that the sending of the signal was
25950 successful. If the
<parameter>timeout
</parameter> is specified (in
25951 milliseconds) and greater than zero, the function waits until the
25952 process is actually terminated or until the given time has passed. If
25953 the process is terminated, the function
25954 returns
<literal>true
</literal>. On timeout, a warning is emitted and
25955 <literal>false
</literal> is returned.
25963 <function>pg_cancel_backend
</function> and
<function>pg_terminate_backend
</function>
25964 send signals (
<systemitem>SIGINT
</systemitem> or
<systemitem>SIGTERM
</systemitem>
25965 respectively) to backend processes identified by process ID.
25966 The process ID of an active backend can be found from
25967 the
<structfield>pid
</structfield> column of the
25968 <structname>pg_stat_activity
</structname> view, or by listing the
25969 <command>postgres
</command> processes on the server (using
25970 <application>ps
</application> on Unix or the
<application>Task
25971 Manager
</application> on
<productname>Windows
</productname>).
25972 The role of an active backend can be found from the
25973 <structfield>usename
</structfield> column of the
25974 <structname>pg_stat_activity
</structname> view.
25978 <function>pg_log_backend_memory_contexts
</function> can be used
25979 to log the memory contexts of a backend process. For example:
25981 postgres=# SELECT pg_log_backend_memory_contexts(pg_backend_pid());
25982 pg_log_backend_memory_contexts
25983 --------------------------------
25987 One message for each memory context will be logged. For example:
25989 LOG: logging memory contexts of PID
10377
25990 STATEMENT: SELECT pg_log_backend_memory_contexts(pg_backend_pid());
25991 LOG: level:
0; TopMemoryContext:
80800 total in
6 blocks;
14432 free (
5 chunks);
66368 used
25992 LOG: level:
1; pgstat TabStatusArray lookup hash table:
8192 total in
1 blocks;
1408 free (
0 chunks);
6784 used
25993 LOG: level:
1; TopTransactionContext:
8192 total in
1 blocks;
7720 free (
1 chunks);
472 used
25994 LOG: level:
1; RowDescriptionContext:
8192 total in
1 blocks;
6880 free (
0 chunks);
1312 used
25995 LOG: level:
1; MessageContext:
16384 total in
2 blocks;
5152 free (
0 chunks);
11232 used
25996 LOG: level:
1; Operator class cache:
8192 total in
1 blocks;
512 free (
0 chunks);
7680 used
25997 LOG: level:
1; smgr relation table:
16384 total in
2 blocks;
4544 free (
3 chunks);
11840 used
25998 LOG: level:
1; TransactionAbortContext:
32768 total in
1 blocks;
32504 free (
0 chunks);
264 used
26000 LOG: level:
1; ErrorContext:
8192 total in
1 blocks;
7928 free (
3 chunks);
264 used
26001 LOG: Grand total:
1651920 bytes in
201 blocks;
622360 free (
88 chunks);
1029560 used
26003 If there are more than
100 child contexts under the same parent, the first
26004 100 child contexts are logged, along with a summary of the remaining contexts.
26005 Note that frequent calls to this function could incur significant overhead,
26006 because it may generate a large number of log messages.
26011 <sect2 id=
"functions-admin-backup">
26012 <title>Backup Control Functions
</title>
26015 <primary>backup
</primary>
26019 The functions shown in
<xref
26020 linkend=
"functions-admin-backup-table"/> assist in making on-line backups.
26021 These functions cannot be executed during recovery (except
26022 <function>pg_backup_start
</function>,
26023 <function>pg_backup_stop
</function>,
26024 and
<function>pg_wal_lsn_diff
</function>).
26028 For details about proper usage of these functions, see
26029 <xref linkend=
"continuous-archiving"/>.
26032 <table id=
"functions-admin-backup-table">
26033 <title>Backup Control Functions
</title>
26037 <entry role=
"func_table_entry"><para role=
"func_signature">
26048 <entry role=
"func_table_entry"><para role=
"func_signature">
26050 <primary>pg_create_restore_point
</primary>
26052 <function>pg_create_restore_point
</function> (
<parameter>name
</parameter> <type>text
</type> )
26053 <returnvalue>pg_lsn
</returnvalue>
26056 Creates a named marker record in the write-ahead log that can later be
26057 used as a recovery target, and returns the corresponding write-ahead
26058 log location. The given name can then be used with
26059 <xref linkend=
"guc-recovery-target-name"/> to specify the point up to
26060 which recovery will proceed. Avoid creating multiple restore points
26061 with the same name, since recovery will stop at the first one whose
26062 name matches the recovery target.
26065 This function is restricted to superusers by default, but other users
26066 can be granted EXECUTE to run the function.
26071 <entry role=
"func_table_entry"><para role=
"func_signature">
26073 <primary>pg_current_wal_flush_lsn
</primary>
26075 <function>pg_current_wal_flush_lsn
</function> ()
26076 <returnvalue>pg_lsn
</returnvalue>
26079 Returns the current write-ahead log flush location (see notes below).
26084 <entry role=
"func_table_entry"><para role=
"func_signature">
26086 <primary>pg_current_wal_insert_lsn
</primary>
26088 <function>pg_current_wal_insert_lsn
</function> ()
26089 <returnvalue>pg_lsn
</returnvalue>
26092 Returns the current write-ahead log insert location (see notes below).
26097 <entry role=
"func_table_entry"><para role=
"func_signature">
26099 <primary>pg_current_wal_lsn
</primary>
26101 <function>pg_current_wal_lsn
</function> ()
26102 <returnvalue>pg_lsn
</returnvalue>
26105 Returns the current write-ahead log write location (see notes below).
26110 <entry role=
"func_table_entry"><para role=
"func_signature">
26112 <primary>pg_backup_start
</primary>
26114 <function>pg_backup_start
</function> (
26115 <parameter>label
</parameter> <type>text
</type>
26116 <optional>,
<parameter>fast
</parameter> <type>boolean
</type>
26118 <returnvalue>pg_lsn
</returnvalue>
26121 Prepares the server to begin an on-line backup. The only required
26122 parameter is an arbitrary user-defined label for the backup.
26123 (Typically this would be the name under which the backup dump file
26125 If the optional second parameter is given as
<literal>true
</literal>,
26126 it specifies executing
<function>pg_backup_start
</function> as quickly
26127 as possible. This forces an immediate checkpoint which will cause a
26128 spike in I/O operations, slowing any concurrently executing queries.
26131 This function is restricted to superusers by default, but other users
26132 can be granted EXECUTE to run the function.
26137 <entry role=
"func_table_entry"><para role=
"func_signature">
26139 <primary>pg_backup_stop
</primary>
26141 <function>pg_backup_stop
</function> (
26142 <optional><parameter>wait_for_archive
</parameter> <type>boolean
</type>
26144 <returnvalue>record
</returnvalue>
26145 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
26146 <parameter>labelfile
</parameter> <type>text
</type>,
26147 <parameter>spcmapfile
</parameter> <type>text
</type> )
26150 Finishes performing an on-line backup. The desired contents of the
26151 backup label file and the tablespace map file are returned as part of
26152 the result of the function and must be written to files in the
26153 backup area. These files must not be written to the live data directory
26154 (doing so will cause PostgreSQL to fail to restart in the event of a
26158 There is an optional parameter of type
<type>boolean
</type>.
26159 If false, the function will return immediately after the backup is
26160 completed, without waiting for WAL to be archived. This behavior is
26161 only useful with backup software that independently monitors WAL
26162 archiving. Otherwise, WAL required to make the backup consistent might
26163 be missing and make the backup useless. By default or when this
26164 parameter is true,
<function>pg_backup_stop
</function> will wait for
26165 WAL to be archived when archiving is enabled. (On a standby, this
26166 means that it will wait only when
<varname>archive_mode
</varname> =
26167 <literal>always
</literal>. If write activity on the primary is low,
26168 it may be useful to run
<function>pg_switch_wal
</function> on the
26169 primary in order to trigger an immediate segment switch.)
26172 When executed on a primary, this function also creates a backup
26173 history file in the write-ahead log archive area. The history file
26174 includes the label given to
<function>pg_backup_start
</function>, the
26175 starting and ending write-ahead log locations for the backup, and the
26176 starting and ending times of the backup. After recording the ending
26177 location, the current write-ahead log insertion point is automatically
26178 advanced to the next write-ahead log file, so that the ending
26179 write-ahead log file can be archived immediately to complete the
26183 The result of the function is a single record.
26184 The
<parameter>lsn
</parameter> column holds the backup's ending
26185 write-ahead log location (which again can be ignored). The second
26186 column returns the contents of the backup label file, and the third
26187 column returns the contents of the tablespace map file. These must be
26188 stored as part of the backup and are required as part of the restore
26192 This function is restricted to superusers by default, but other users
26193 can be granted EXECUTE to run the function.
26198 <entry role=
"func_table_entry"><para role=
"func_signature">
26200 <primary>pg_switch_wal
</primary>
26202 <function>pg_switch_wal
</function> ()
26203 <returnvalue>pg_lsn
</returnvalue>
26206 Forces the server to switch to a new write-ahead log file, which
26207 allows the current file to be archived (assuming you are using
26208 continuous archiving). The result is the ending write-ahead log
26209 location plus
1 within the just-completed write-ahead log file. If
26210 there has been no write-ahead log activity since the last write-ahead
26211 log switch,
<function>pg_switch_wal
</function> does nothing and
26212 returns the start location of the write-ahead log file currently in
26216 This function is restricted to superusers by default, but other users
26217 can be granted EXECUTE to run the function.
26222 <entry role=
"func_table_entry"><para role=
"func_signature">
26224 <primary>pg_walfile_name
</primary>
26226 <function>pg_walfile_name
</function> (
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
26227 <returnvalue>text
</returnvalue>
26230 Converts a write-ahead log location to the name of the WAL file
26231 holding that location.
26236 <entry role=
"func_table_entry"><para role=
"func_signature">
26238 <primary>pg_walfile_name_offset
</primary>
26240 <function>pg_walfile_name_offset
</function> (
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
26241 <returnvalue>record
</returnvalue>
26242 (
<parameter>file_name
</parameter> <type>text
</type>,
26243 <parameter>file_offset
</parameter> <type>integer
</type> )
26246 Converts a write-ahead log location to a WAL file name and byte offset
26252 <entry role=
"func_table_entry"><para role=
"func_signature">
26254 <primary>pg_split_walfile_name
</primary>
26256 <function>pg_split_walfile_name
</function> (
<parameter>file_name
</parameter> <type>text
</type> )
26257 <returnvalue>record
</returnvalue>
26258 (
<parameter>segment_number
</parameter> <type>numeric
</type>,
26259 <parameter>timeline_id
</parameter> <type>bigint
</type> )
26262 Extracts the sequence number and timeline ID from a WAL file
26268 <entry role=
"func_table_entry"><para role=
"func_signature">
26270 <primary>pg_wal_lsn_diff
</primary>
26272 <function>pg_wal_lsn_diff
</function> (
<parameter>lsn1
</parameter> <type>pg_lsn
</type>,
<parameter>lsn2
</parameter> <type>pg_lsn
</type> )
26273 <returnvalue>numeric
</returnvalue>
26276 Calculates the difference in bytes (
<parameter>lsn1
</parameter> -
<parameter>lsn2
</parameter>) between two write-ahead log
26277 locations. This can be used
26278 with
<structname>pg_stat_replication
</structname> or some of the
26279 functions shown in
<xref linkend=
"functions-admin-backup-table"/> to
26280 get the replication lag.
26288 <function>pg_current_wal_lsn
</function> displays the current write-ahead
26289 log write location in the same format used by the above functions.
26290 Similarly,
<function>pg_current_wal_insert_lsn
</function> displays the
26291 current write-ahead log insertion location
26292 and
<function>pg_current_wal_flush_lsn
</function> displays the current
26293 write-ahead log flush location. The insertion location is
26294 the
<quote>logical
</quote> end of the write-ahead log at any instant,
26295 while the write location is the end of what has actually been written out
26296 from the server's internal buffers, and the flush location is the last
26297 location known to be written to durable storage. The write location is the
26298 end of what can be examined from outside the server, and is usually what
26299 you want if you are interested in archiving partially-complete write-ahead
26300 log files. The insertion and flush locations are made available primarily
26301 for server debugging purposes. These are all read-only operations and do
26302 not require superuser permissions.
26306 You can use
<function>pg_walfile_name_offset
</function> to extract the
26307 corresponding write-ahead log file name and byte offset from
26308 a
<type>pg_lsn
</type> value. For example:
26310 postgres=# SELECT * FROM pg_walfile_name_offset((pg_backup_stop()).lsn);
26311 file_name | file_offset
26312 --------------------------+-------------
26313 00000001000000000000000D |
4039624
26316 Similarly,
<function>pg_walfile_name
</function> extracts just the write-ahead log file name.
26317 When the given write-ahead log location is exactly at a write-ahead log file boundary, both
26318 these functions return the name of the preceding write-ahead log file.
26319 This is usually the desired behavior for managing write-ahead log archiving
26320 behavior, since the preceding file is the last one that currently
26321 needs to be archived.
26325 <function>pg_split_walfile_name
</function> is useful to compute a
26326 <acronym>LSN
</acronym> from a file offset and WAL file name, for example:
26328 postgres=# \set file_name '
000000010000000100C000AB'
26329 postgres=# \set offset
256
26330 postgres=# SELECT '
0/
0'::pg_lsn + pd.segment_number * ps.setting::int + :offset AS lsn
26331 FROM pg_split_walfile_name(:'file_name') pd,
26332 pg_show_all_settings() ps
26333 WHERE ps.name = 'wal_segment_size';
26343 <sect2 id=
"functions-recovery-control">
26344 <title>Recovery Control Functions
</title>
26347 The functions shown in
<xref
26348 linkend=
"functions-recovery-info-table"/> provide information
26349 about the current status of a standby server.
26350 These functions may be executed both during recovery and in normal running.
26353 <table id=
"functions-recovery-info-table">
26354 <title>Recovery Information Functions
</title>
26358 <entry role=
"func_table_entry"><para role=
"func_signature">
26369 <entry role=
"func_table_entry"><para role=
"func_signature">
26371 <primary>pg_is_in_recovery
</primary>
26373 <function>pg_is_in_recovery
</function> ()
26374 <returnvalue>boolean
</returnvalue>
26377 Returns true if recovery is still in progress.
26382 <entry role=
"func_table_entry"><para role=
"func_signature">
26384 <primary>pg_last_wal_receive_lsn
</primary>
26386 <function>pg_last_wal_receive_lsn
</function> ()
26387 <returnvalue>pg_lsn
</returnvalue>
26390 Returns the last write-ahead log location that has been received and
26391 synced to disk by streaming replication. While streaming replication
26392 is in progress this will increase monotonically. If recovery has
26393 completed then this will remain static at the location of the last WAL
26394 record received and synced to disk during recovery. If streaming
26395 replication is disabled, or if it has not yet started, the function
26396 returns
<literal>NULL
</literal>.
26401 <entry role=
"func_table_entry"><para role=
"func_signature">
26403 <primary>pg_last_wal_replay_lsn
</primary>
26405 <function>pg_last_wal_replay_lsn
</function> ()
26406 <returnvalue>pg_lsn
</returnvalue>
26409 Returns the last write-ahead log location that has been replayed
26410 during recovery. If recovery is still in progress this will increase
26411 monotonically. If recovery has completed then this will remain
26412 static at the location of the last WAL record applied during recovery.
26413 When the server has been started normally without recovery, the
26414 function returns
<literal>NULL
</literal>.
26419 <entry role=
"func_table_entry"><para role=
"func_signature">
26421 <primary>pg_last_xact_replay_timestamp
</primary>
26423 <function>pg_last_xact_replay_timestamp
</function> ()
26424 <returnvalue>timestamp with time zone
</returnvalue>
26427 Returns the time stamp of the last transaction replayed during
26428 recovery. This is the time at which the commit or abort WAL record
26429 for that transaction was generated on the primary. If no transactions
26430 have been replayed during recovery, the function
26431 returns
<literal>NULL
</literal>. Otherwise, if recovery is still in
26432 progress this will increase monotonically. If recovery has completed
26433 then this will remain static at the time of the last transaction
26434 applied during recovery. When the server has been started normally
26435 without recovery, the function returns
<literal>NULL
</literal>.
26440 <entry role=
"func_table_entry"><para role=
"func_signature">
26442 <primary>pg_get_wal_resource_managers
</primary>
26444 <function>pg_get_wal_resource_managers
</function> ()
26445 <returnvalue>setof record
</returnvalue>
26446 (
<parameter>rm_id
</parameter> <type>integer
</type>,
26447 <parameter>rm_name
</parameter> <type>text
</type>,
26448 <parameter>rm_builtin
</parameter> <type>boolean
</type> )
26451 Returns the currently-loaded WAL resource managers in the system. The
26452 column
<parameter>rm_builtin
</parameter> indicates whether it's a
26453 built-in resource manager, or a custom resource manager loaded by an
26462 The functions shown in
<xref
26463 linkend=
"functions-recovery-control-table"/> control the progress of recovery.
26464 These functions may be executed only during recovery.
26467 <table id=
"functions-recovery-control-table">
26468 <title>Recovery Control Functions
</title>
26472 <entry role=
"func_table_entry"><para role=
"func_signature">
26483 <entry role=
"func_table_entry"><para role=
"func_signature">
26485 <primary>pg_is_wal_replay_paused
</primary>
26487 <function>pg_is_wal_replay_paused
</function> ()
26488 <returnvalue>boolean
</returnvalue>
26491 Returns true if recovery pause is requested.
26496 <entry role=
"func_table_entry"><para role=
"func_signature">
26498 <primary>pg_get_wal_replay_pause_state
</primary>
26500 <function>pg_get_wal_replay_pause_state
</function> ()
26501 <returnvalue>text
</returnvalue>
26504 Returns recovery pause state. The return values are
<literal>
26505 not paused
</literal> if pause is not requested,
<literal>
26506 pause requested
</literal> if pause is requested but recovery is
26507 not yet paused, and
<literal>paused
</literal> if the recovery is
26513 <entry role=
"func_table_entry"><para role=
"func_signature">
26515 <primary>pg_promote
</primary>
26517 <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> )
26518 <returnvalue>boolean
</returnvalue>
26521 Promotes a standby server to primary status.
26522 With
<parameter>wait
</parameter> set to
<literal>true
</literal> (the
26523 default), the function waits until promotion is completed
26524 or
<parameter>wait_seconds
</parameter> seconds have passed, and
26525 returns
<literal>true
</literal> if promotion is successful
26526 and
<literal>false
</literal> otherwise.
26527 If
<parameter>wait
</parameter> is set to
<literal>false
</literal>, the
26528 function returns
<literal>true
</literal> immediately after sending a
26529 <literal>SIGUSR1
</literal> signal to the postmaster to trigger
26533 This function is restricted to superusers by default, but other users
26534 can be granted EXECUTE to run the function.
26539 <entry role=
"func_table_entry"><para role=
"func_signature">
26541 <primary>pg_wal_replay_pause
</primary>
26543 <function>pg_wal_replay_pause
</function> ()
26544 <returnvalue>void
</returnvalue>
26547 Request to pause recovery. A request doesn't mean that recovery stops
26548 right away. If you want a guarantee that recovery is actually paused,
26549 you need to check for the recovery pause state returned by
26550 <function>pg_get_wal_replay_pause_state()
</function>. Note that
26551 <function>pg_is_wal_replay_paused()
</function> returns whether a request
26552 is made. While recovery is paused, no further database changes are applied.
26553 If hot standby is active, all new queries will see the same consistent
26554 snapshot of the database, and no further query conflicts will be generated
26555 until recovery is resumed.
26558 This function is restricted to superusers by default, but other users
26559 can be granted EXECUTE to run the function.
26564 <entry role=
"func_table_entry"><para role=
"func_signature">
26566 <primary>pg_wal_replay_resume
</primary>
26568 <function>pg_wal_replay_resume
</function> ()
26569 <returnvalue>void
</returnvalue>
26572 Restarts recovery if it was paused.
26575 This function is restricted to superusers by default, but other users
26576 can be granted EXECUTE to run the function.
26584 <function>pg_wal_replay_pause
</function> and
26585 <function>pg_wal_replay_resume
</function> cannot be executed while
26586 a promotion is ongoing. If a promotion is triggered while recovery
26587 is paused, the paused state ends and promotion continues.
26591 If streaming replication is disabled, the paused state may continue
26592 indefinitely without a problem. If streaming replication is in
26593 progress then WAL records will continue to be received, which will
26594 eventually fill available disk space, depending upon the duration of
26595 the pause, the rate of WAL generation and available disk space.
26600 <sect2 id=
"functions-snapshot-synchronization">
26601 <title>Snapshot Synchronization Functions
</title>
26604 <productname>PostgreSQL
</productname> allows database sessions to synchronize their
26605 snapshots. A
<firstterm>snapshot
</firstterm> determines which data is visible to the
26606 transaction that is using the snapshot. Synchronized snapshots are
26607 necessary when two or more sessions need to see identical content in the
26608 database. If two sessions just start their transactions independently,
26609 there is always a possibility that some third transaction commits
26610 between the executions of the two
<command>START TRANSACTION
</command> commands,
26611 so that one session sees the effects of that transaction and the other
26616 To solve this problem,
<productname>PostgreSQL
</productname> allows a transaction to
26617 <firstterm>export
</firstterm> the snapshot it is using. As long as the exporting
26618 transaction remains open, other transactions can
<firstterm>import
</firstterm> its
26619 snapshot, and thereby be guaranteed that they see exactly the same view
26620 of the database that the first transaction sees. But note that any
26621 database changes made by any one of these transactions remain invisible
26622 to the other transactions, as is usual for changes made by uncommitted
26623 transactions. So the transactions are synchronized with respect to
26624 pre-existing data, but act normally for changes they make themselves.
26628 Snapshots are exported with the
<function>pg_export_snapshot
</function> function,
26629 shown in
<xref linkend=
"functions-snapshot-synchronization-table"/>, and
26630 imported with the
<xref linkend=
"sql-set-transaction"/> command.
26633 <table id=
"functions-snapshot-synchronization-table">
26634 <title>Snapshot Synchronization Functions
</title>
26638 <entry role=
"func_table_entry"><para role=
"func_signature">
26649 <entry role=
"func_table_entry"><para role=
"func_signature">
26651 <primary>pg_export_snapshot
</primary>
26653 <function>pg_export_snapshot
</function> ()
26654 <returnvalue>text
</returnvalue>
26657 Saves the transaction's current snapshot and returns
26658 a
<type>text
</type> string identifying the snapshot. This string must
26659 be passed (outside the database) to clients that want to import the
26660 snapshot. The snapshot is available for import only until the end of
26661 the transaction that exported it.
26664 A transaction can export more than one snapshot, if needed. Note that
26665 doing so is only useful in
<literal>READ COMMITTED
</literal>
26666 transactions, since in
<literal>REPEATABLE READ
</literal> and higher
26667 isolation levels, transactions use the same snapshot throughout their
26668 lifetime. Once a transaction has exported any snapshots, it cannot be
26669 prepared with
<xref linkend=
"sql-prepare-transaction"/>.
26678 <sect2 id=
"functions-replication">
26679 <title>Replication Management Functions
</title>
26682 The functions shown
26683 in
<xref linkend=
"functions-replication-table"/> are for
26684 controlling and interacting with replication features.
26685 See
<xref linkend=
"streaming-replication"/>,
26686 <xref linkend=
"streaming-replication-slots"/>, and
26687 <xref linkend=
"replication-origins"/>
26688 for information about the underlying features.
26689 Use of functions for replication origin is only allowed to the
26690 superuser by default, but may be allowed to other users by using the
26691 <literal>GRANT
</literal> command.
26692 Use of functions for replication slots is restricted to superusers
26693 and users having
<literal>REPLICATION
</literal> privilege.
26697 Many of these functions have equivalent commands in the replication
26698 protocol; see
<xref linkend=
"protocol-replication"/>.
26702 The functions described in
26703 <xref linkend=
"functions-admin-backup"/>,
26704 <xref linkend=
"functions-recovery-control"/>, and
26705 <xref linkend=
"functions-snapshot-synchronization"/>
26706 are also relevant for replication.
26709 <table id=
"functions-replication-table">
26710 <title>Replication Management Functions
</title>
26714 <entry role=
"func_table_entry"><para role=
"func_signature">
26725 <entry role=
"func_table_entry"><para role=
"func_signature">
26727 <primary>pg_create_physical_replication_slot
</primary>
26729 <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> )
26730 <returnvalue>record
</returnvalue>
26731 (
<parameter>slot_name
</parameter> <type>name
</type>,
26732 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
26735 Creates a new physical replication slot named
26736 <parameter>slot_name
</parameter>. The optional second parameter,
26737 when
<literal>true
</literal>, specifies that the
<acronym>LSN
</acronym> for this
26738 replication slot be reserved immediately; otherwise
26739 the
<acronym>LSN
</acronym> is reserved on first connection from a streaming
26740 replication client. Streaming changes from a physical slot is only
26741 possible with the streaming-replication protocol
—
26742 see
<xref linkend=
"protocol-replication"/>. The optional third
26743 parameter,
<parameter>temporary
</parameter>, when set to true, specifies that
26744 the slot should not be permanently stored to disk and is only meant
26745 for use by the current session. Temporary slots are also
26746 released upon any error. This function corresponds
26747 to the replication protocol command
<literal>CREATE_REPLICATION_SLOT
26748 ... PHYSICAL
</literal>.
26753 <entry role=
"func_table_entry"><para role=
"func_signature">
26755 <primary>pg_drop_replication_slot
</primary>
26757 <function>pg_drop_replication_slot
</function> (
<parameter>slot_name
</parameter> <type>name
</type> )
26758 <returnvalue>void
</returnvalue>
26761 Drops the physical or logical replication slot
26762 named
<parameter>slot_name
</parameter>. Same as replication protocol
26763 command
<literal>DROP_REPLICATION_SLOT
</literal>. For logical slots, this must
26764 be called while connected to the same database the slot was created on.
26769 <entry role=
"func_table_entry"><para role=
"func_signature">
26771 <primary>pg_create_logical_replication_slot
</primary>
26773 <function>pg_create_logical_replication_slot
</function> (
<parameter>slot_name
</parameter> <type>name
</type>,
<parameter>plugin
</parameter> <type>name
</type> <optional>,
<parameter>temporary
</parameter> <type>boolean
</type>,
<parameter>twophase
</parameter> <type>boolean
</type> </optional> )
26774 <returnvalue>record
</returnvalue>
26775 (
<parameter>slot_name
</parameter> <type>name
</type>,
26776 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
26779 Creates a new logical (decoding) replication slot named
26780 <parameter>slot_name
</parameter> using the output plugin
26781 <parameter>plugin
</parameter>. The optional third
26782 parameter,
<parameter>temporary
</parameter>, when set to true, specifies that
26783 the slot should not be permanently stored to disk and is only meant
26784 for use by the current session. Temporary slots are also
26785 released upon any error. The optional fourth parameter,
26786 <parameter>twophase
</parameter>, when set to true, specifies
26787 that the decoding of prepared transactions is enabled for this
26788 slot. A call to this function has the same effect as the replication
26789 protocol command
<literal>CREATE_REPLICATION_SLOT ... LOGICAL
</literal>.
26794 <entry role=
"func_table_entry"><para role=
"func_signature">
26796 <primary>pg_copy_physical_replication_slot
</primary>
26798 <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> )
26799 <returnvalue>record
</returnvalue>
26800 (
<parameter>slot_name
</parameter> <type>name
</type>,
26801 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
26804 Copies an existing physical replication slot named
<parameter>src_slot_name
</parameter>
26805 to a physical replication slot named
<parameter>dst_slot_name
</parameter>.
26806 The copied physical slot starts to reserve WAL from the same
<acronym>LSN
</acronym> as the
26808 <parameter>temporary
</parameter> is optional. If
<parameter>temporary
</parameter>
26809 is omitted, the same value as the source slot is used.
26814 <entry role=
"func_table_entry"><para role=
"func_signature">
26816 <primary>pg_copy_logical_replication_slot
</primary>
26818 <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> )
26819 <returnvalue>record
</returnvalue>
26820 (
<parameter>slot_name
</parameter> <type>name
</type>,
26821 <parameter>lsn
</parameter> <type>pg_lsn
</type> )
26824 Copies an existing logical replication slot
26825 named
<parameter>src_slot_name
</parameter> to a logical replication
26826 slot named
<parameter>dst_slot_name
</parameter>, optionally changing
26827 the output plugin and persistence. The copied logical slot starts
26828 from the same
<acronym>LSN
</acronym> as the source logical slot. Both
26829 <parameter>temporary
</parameter> and
<parameter>plugin
</parameter> are
26830 optional; if they are omitted, the values of the source slot are used.
26835 <entry role=
"func_table_entry"><para role=
"func_signature">
26837 <primary>pg_logical_slot_get_changes
</primary>
26839 <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> )
26840 <returnvalue>setof record
</returnvalue>
26841 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
26842 <parameter>xid
</parameter> <type>xid
</type>,
26843 <parameter>data
</parameter> <type>text
</type> )
26846 Returns changes in the slot
<parameter>slot_name
</parameter>, starting
26847 from the point from which changes have been consumed last. If
26848 <parameter>upto_lsn
</parameter>
26849 and
<parameter>upto_nchanges
</parameter> are NULL,
26850 logical decoding will continue until end of WAL. If
26851 <parameter>upto_lsn
</parameter> is non-NULL, decoding will include only
26852 those transactions which commit prior to the specified LSN. If
26853 <parameter>upto_nchanges
</parameter> is non-NULL, decoding will
26854 stop when the number of rows produced by decoding exceeds
26855 the specified value. Note, however, that the actual number of
26856 rows returned may be larger, since this limit is only checked after
26857 adding the rows produced when decoding each new transaction commit.
26862 <entry role=
"func_table_entry"><para role=
"func_signature">
26864 <primary>pg_logical_slot_peek_changes
</primary>
26866 <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> )
26867 <returnvalue>setof record
</returnvalue>
26868 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
26869 <parameter>xid
</parameter> <type>xid
</type>,
26870 <parameter>data
</parameter> <type>text
</type> )
26874 the
<function>pg_logical_slot_get_changes()
</function> function,
26875 except that changes are not consumed; that is, they will be returned
26876 again on future calls.
26881 <entry role=
"func_table_entry"><para role=
"func_signature">
26883 <primary>pg_logical_slot_get_binary_changes
</primary>
26885 <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> )
26886 <returnvalue>setof record
</returnvalue>
26887 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
26888 <parameter>xid
</parameter> <type>xid
</type>,
26889 <parameter>data
</parameter> <type>bytea
</type> )
26893 the
<function>pg_logical_slot_get_changes()
</function> function,
26894 except that changes are returned as
<type>bytea
</type>.
26899 <entry role=
"func_table_entry"><para role=
"func_signature">
26901 <primary>pg_logical_slot_peek_binary_changes
</primary>
26903 <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> )
26904 <returnvalue>setof record
</returnvalue>
26905 (
<parameter>lsn
</parameter> <type>pg_lsn
</type>,
26906 <parameter>xid
</parameter> <type>xid
</type>,
26907 <parameter>data
</parameter> <type>bytea
</type> )
26911 the
<function>pg_logical_slot_peek_changes()
</function> function,
26912 except that changes are returned as
<type>bytea
</type>.
26917 <entry role=
"func_table_entry"><para role=
"func_signature">
26919 <primary>pg_replication_slot_advance
</primary>
26921 <function>pg_replication_slot_advance
</function> (
<parameter>slot_name
</parameter> <type>name
</type>,
<parameter>upto_lsn
</parameter> <type>pg_lsn
</type> )
26922 <returnvalue>record
</returnvalue>
26923 (
<parameter>slot_name
</parameter> <type>name
</type>,
26924 <parameter>end_lsn
</parameter> <type>pg_lsn
</type> )
26927 Advances the current confirmed position of a replication slot named
26928 <parameter>slot_name
</parameter>. The slot will not be moved backwards,
26929 and it will not be moved beyond the current insert location. Returns
26930 the name of the slot and the actual position that it was advanced to.
26931 The updated slot position information is written out at the next
26932 checkpoint if any advancing is done. So in the event of a crash, the
26933 slot may return to an earlier position.
26938 <entry id=
"pg-replication-origin-create" role=
"func_table_entry"><para role=
"func_signature">
26940 <primary>pg_replication_origin_create
</primary>
26942 <function>pg_replication_origin_create
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
26943 <returnvalue>oid
</returnvalue>
26946 Creates a replication origin with the given external
26947 name, and returns the internal ID assigned to it.
26952 <entry id=
"pg-replication-origin-drop" role=
"func_table_entry"><para role=
"func_signature">
26954 <primary>pg_replication_origin_drop
</primary>
26956 <function>pg_replication_origin_drop
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
26957 <returnvalue>void
</returnvalue>
26960 Deletes a previously-created replication origin, including any
26961 associated replay progress.
26966 <entry role=
"func_table_entry"><para role=
"func_signature">
26968 <primary>pg_replication_origin_oid
</primary>
26970 <function>pg_replication_origin_oid
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
26971 <returnvalue>oid
</returnvalue>
26974 Looks up a replication origin by name and returns the internal ID. If
26975 no such replication origin is found,
<literal>NULL
</literal> is
26981 <entry id=
"pg-replication-origin-session-setup" role=
"func_table_entry"><para role=
"func_signature">
26983 <primary>pg_replication_origin_session_setup
</primary>
26985 <function>pg_replication_origin_session_setup
</function> (
<parameter>node_name
</parameter> <type>text
</type> )
26986 <returnvalue>void
</returnvalue>
26989 Marks the current session as replaying from the given
26990 origin, allowing replay progress to be tracked.
26991 Can only be used if no origin is currently selected.
26992 Use
<function>pg_replication_origin_session_reset
</function> to undo.
26997 <entry role=
"func_table_entry"><para role=
"func_signature">
26999 <primary>pg_replication_origin_session_reset
</primary>
27001 <function>pg_replication_origin_session_reset
</function> ()
27002 <returnvalue>void
</returnvalue>
27005 Cancels the effects
27006 of
<function>pg_replication_origin_session_setup()
</function>.
27011 <entry role=
"func_table_entry"><para role=
"func_signature">
27013 <primary>pg_replication_origin_session_is_setup
</primary>
27015 <function>pg_replication_origin_session_is_setup
</function> ()
27016 <returnvalue>boolean
</returnvalue>
27019 Returns true if a replication origin has been selected in the
27025 <entry id=
"pg-replication-origin-session-progress" role=
"func_table_entry"><para role=
"func_signature">
27027 <primary>pg_replication_origin_session_progress
</primary>
27029 <function>pg_replication_origin_session_progress
</function> (
<parameter>flush
</parameter> <type>boolean
</type> )
27030 <returnvalue>pg_lsn
</returnvalue>
27033 Returns the replay location for the replication origin selected in
27034 the current session. The parameter
<parameter>flush
</parameter>
27035 determines whether the corresponding local transaction will be
27036 guaranteed to have been flushed to disk or not.
27041 <entry id=
"pg-replication-origin-xact-setup" role=
"func_table_entry"><para role=
"func_signature">
27043 <primary>pg_replication_origin_xact_setup
</primary>
27045 <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> )
27046 <returnvalue>void
</returnvalue>
27049 Marks the current transaction as replaying a transaction that has
27050 committed at the given
<acronym>LSN
</acronym> and timestamp. Can
27051 only be called when a replication origin has been selected
27052 using
<function>pg_replication_origin_session_setup
</function>.
27057 <entry id=
"pg-replication-origin-xact-reset" role=
"func_table_entry"><para role=
"func_signature">
27059 <primary>pg_replication_origin_xact_reset
</primary>
27061 <function>pg_replication_origin_xact_reset
</function> ()
27062 <returnvalue>void
</returnvalue>
27065 Cancels the effects of
27066 <function>pg_replication_origin_xact_setup()
</function>.
27071 <entry id=
"pg-replication-origin-advance" role=
"func_table_entry"><para role=
"func_signature">
27073 <primary>pg_replication_origin_advance
</primary>
27075 <function>pg_replication_origin_advance
</function> (
<parameter>node_name
</parameter> <type>text
</type>,
<parameter>lsn
</parameter> <type>pg_lsn
</type> )
27076 <returnvalue>void
</returnvalue>
27079 Sets replication progress for the given node to the given
27080 location. This is primarily useful for setting up the initial
27081 location, or setting a new location after configuration changes and
27082 similar. Be aware that careless use of this function can lead to
27083 inconsistently replicated data.
27088 <entry id=
"pg-replication-origin-progress" role=
"func_table_entry"><para role=
"func_signature">
27090 <primary>pg_replication_origin_progress
</primary>
27092 <function>pg_replication_origin_progress
</function> (
<parameter>node_name
</parameter> <type>text
</type>,
<parameter>flush
</parameter> <type>boolean
</type> )
27093 <returnvalue>pg_lsn
</returnvalue>
27096 Returns the replay location for the given replication origin. The
27097 parameter
<parameter>flush
</parameter> determines whether the
27098 corresponding local transaction will be guaranteed to have been
27099 flushed to disk or not.
27104 <entry id=
"pg-logical-emit-message" role=
"func_table_entry"><para role=
"func_signature">
27106 <primary>pg_logical_emit_message
</primary>
27108 <function>pg_logical_emit_message
</function> (
<parameter>transactional
</parameter> <type>boolean
</type>,
<parameter>prefix
</parameter> <type>text
</type>,
<parameter>content
</parameter> <type>text
</type> )
27109 <returnvalue>pg_lsn
</returnvalue>
27111 <para role=
"func_signature">
27112 <function>pg_logical_emit_message
</function> (
<parameter>transactional
</parameter> <type>boolean
</type>,
<parameter>prefix
</parameter> <type>text
</type>,
<parameter>content
</parameter> <type>bytea
</type> )
27113 <returnvalue>pg_lsn
</returnvalue>
27116 Emits a logical decoding message. This can be used to pass generic
27117 messages to logical decoding plugins through
27118 WAL. The
<parameter>transactional
</parameter> parameter specifies if
27119 the message should be part of the current transaction, or if it should
27120 be written immediately and decoded as soon as the logical decoder
27121 reads the record. The
<parameter>prefix
</parameter> parameter is a
27122 textual prefix that can be used by logical decoding plugins to easily
27123 recognize messages that are interesting for them.
27124 The
<parameter>content
</parameter> parameter is the content of the
27125 message, given either in text or binary form.
27134 <sect2 id=
"functions-admin-dbobject">
27135 <title>Database Object Management Functions
</title>
27138 The functions shown in
<xref linkend=
"functions-admin-dbsize"/> calculate
27139 the disk space usage of database objects, or assist in presentation
27140 or understanding of usage results.
<literal>bigint
</literal> results
27141 are measured in bytes. If an OID that does
27142 not represent an existing object is passed to one of these
27143 functions,
<literal>NULL
</literal> is returned.
27146 <table id=
"functions-admin-dbsize">
27147 <title>Database Object Size Functions
</title>
27151 <entry role=
"func_table_entry"><para role=
"func_signature">
27162 <entry role=
"func_table_entry"><para role=
"func_signature">
27164 <primary>pg_column_size
</primary>
27166 <function>pg_column_size
</function> (
<type>"any"</type> )
27167 <returnvalue>integer
</returnvalue>
27170 Shows the number of bytes used to store any individual data value. If
27171 applied directly to a table column value, this reflects any
27172 compression that was done.
27177 <entry role=
"func_table_entry"><para role=
"func_signature">
27179 <primary>pg_column_compression
</primary>
27181 <function>pg_column_compression
</function> (
<type>"any"</type> )
27182 <returnvalue>text
</returnvalue>
27185 Shows the compression algorithm that was used to compress
27186 an individual variable-length value. Returns
<literal>NULL
</literal>
27187 if the value is not compressed.
27192 <entry role=
"func_table_entry"><para role=
"func_signature">
27194 <primary>pg_database_size
</primary>
27196 <function>pg_database_size
</function> (
<type>name
</type> )
27197 <returnvalue>bigint
</returnvalue>
27199 <para role=
"func_signature">
27200 <function>pg_database_size
</function> (
<type>oid
</type> )
27201 <returnvalue>bigint
</returnvalue>
27204 Computes the total disk space used by the database with the specified
27205 name or OID. To use this function, you must
27206 have
<literal>CONNECT
</literal> privilege on the specified database
27207 (which is granted by default) or have privileges of
27208 the
<literal>pg_read_all_stats
</literal> role.
27213 <entry role=
"func_table_entry"><para role=
"func_signature">
27215 <primary>pg_indexes_size
</primary>
27217 <function>pg_indexes_size
</function> (
<type>regclass
</type> )
27218 <returnvalue>bigint
</returnvalue>
27221 Computes the total disk space used by indexes attached to the
27227 <entry role=
"func_table_entry"><para role=
"func_signature">
27229 <primary>pg_relation_size
</primary>
27231 <function>pg_relation_size
</function> (
<parameter>relation
</parameter> <type>regclass
</type> <optional>,
<parameter>fork
</parameter> <type>text
</type> </optional> )
27232 <returnvalue>bigint
</returnvalue>
27235 Computes the disk space used by one
<quote>fork
</quote> of the
27236 specified relation. (Note that for most purposes it is more
27237 convenient to use the higher-level
27238 functions
<function>pg_total_relation_size
</function>
27239 or
<function>pg_table_size
</function>, which sum the sizes of all
27240 forks.) With one argument, this returns the size of the main data
27241 fork of the relation. The second argument can be provided to specify
27242 which fork to examine:
27243 <itemizedlist spacing=
"compact">
27246 <literal>main
</literal> returns the size of the main
27247 data fork of the relation.
27252 <literal>fsm
</literal> returns the size of the Free Space Map
27253 (see
<xref linkend=
"storage-fsm"/>) associated with the relation.
27258 <literal>vm
</literal> returns the size of the Visibility Map
27259 (see
<xref linkend=
"storage-vm"/>) associated with the relation.
27264 <literal>init
</literal> returns the size of the initialization
27265 fork, if any, associated with the relation.
27273 <entry role=
"func_table_entry"><para role=
"func_signature">
27275 <primary>pg_size_bytes
</primary>
27277 <function>pg_size_bytes
</function> (
<type>text
</type> )
27278 <returnvalue>bigint
</returnvalue>
27281 Converts a size in human-readable format (as returned
27282 by
<function>pg_size_pretty
</function>) into bytes. Valid units are
27283 <literal>bytes
</literal>,
<literal>B
</literal>,
<literal>kB
</literal>,
27284 <literal>MB
</literal>,
<literal>GB
</literal>,
<literal>TB
</literal>,
27285 and
<literal>PB
</literal>.
27290 <entry role=
"func_table_entry"><para role=
"func_signature">
27292 <primary>pg_size_pretty
</primary>
27294 <function>pg_size_pretty
</function> (
<type>bigint
</type> )
27295 <returnvalue>text
</returnvalue>
27297 <para role=
"func_signature">
27298 <function>pg_size_pretty
</function> (
<type>numeric
</type> )
27299 <returnvalue>text
</returnvalue>
27302 Converts a size in bytes into a more easily human-readable format with
27303 size units (bytes, kB, MB, GB, TB, or PB as appropriate). Note that the
27304 units are powers of
2 rather than powers of
10, so
1kB is
1024 bytes,
27305 1MB is
1024<superscript>2</superscript> =
1048576 bytes, and so on.
27310 <entry role=
"func_table_entry"><para role=
"func_signature">
27312 <primary>pg_table_size
</primary>
27314 <function>pg_table_size
</function> (
<type>regclass
</type> )
27315 <returnvalue>bigint
</returnvalue>
27318 Computes the disk space used by the specified table, excluding indexes
27319 (but including its TOAST table if any, free space map, and visibility
27325 <entry role=
"func_table_entry"><para role=
"func_signature">
27327 <primary>pg_tablespace_size
</primary>
27329 <function>pg_tablespace_size
</function> (
<type>name
</type> )
27330 <returnvalue>bigint
</returnvalue>
27332 <para role=
"func_signature">
27333 <function>pg_tablespace_size
</function> (
<type>oid
</type> )
27334 <returnvalue>bigint
</returnvalue>
27337 Computes the total disk space used in the tablespace with the
27338 specified name or OID. To use this function, you must
27339 have
<literal>CREATE
</literal> privilege on the specified tablespace
27340 or have privileges of the
<literal>pg_read_all_stats
</literal> role,
27341 unless it is the default tablespace for the current database.
27346 <entry role=
"func_table_entry"><para role=
"func_signature">
27348 <primary>pg_total_relation_size
</primary>
27350 <function>pg_total_relation_size
</function> (
<type>regclass
</type> )
27351 <returnvalue>bigint
</returnvalue>
27354 Computes the total disk space used by the specified table, including
27355 all indexes and
<acronym>TOAST
</acronym> data. The result is
27356 equivalent to
<function>pg_table_size
</function>
27357 <literal>+
</literal> <function>pg_indexes_size
</function>.
27365 The functions above that operate on tables or indexes accept a
27366 <type>regclass
</type> argument, which is simply the OID of the table or index
27367 in the
<structname>pg_class
</structname> system catalog. You do not have to look up
27368 the OID by hand, however, since the
<type>regclass
</type> data type's input
27369 converter will do the work for you. See
<xref linkend=
"datatype-oid"/>
27374 The functions shown in
<xref linkend=
"functions-admin-dblocation"/> assist
27375 in identifying the specific disk files associated with database objects.
27378 <table id=
"functions-admin-dblocation">
27379 <title>Database Object Location Functions
</title>
27383 <entry role=
"func_table_entry"><para role=
"func_signature">
27394 <entry role=
"func_table_entry"><para role=
"func_signature">
27396 <primary>pg_relation_filenode
</primary>
27398 <function>pg_relation_filenode
</function> (
<parameter>relation
</parameter> <type>regclass
</type> )
27399 <returnvalue>oid
</returnvalue>
27402 Returns the
<quote>filenode
</quote> number currently assigned to the
27403 specified relation. The filenode is the base component of the file
27404 name(s) used for the relation (see
27405 <xref linkend=
"storage-file-layout"/> for more information).
27406 For most relations the result is the same as
27407 <structname>pg_class
</structname>.
<structfield>relfilenode
</structfield>,
27408 but for certain system catalogs
<structfield>relfilenode
</structfield>
27409 is zero and this function must be used to get the correct value. The
27410 function returns NULL if passed a relation that does not have storage,
27416 <entry role=
"func_table_entry"><para role=
"func_signature">
27418 <primary>pg_relation_filepath
</primary>
27420 <function>pg_relation_filepath
</function> (
<parameter>relation
</parameter> <type>regclass
</type> )
27421 <returnvalue>text
</returnvalue>
27424 Returns the entire file path name (relative to the database cluster's
27425 data directory,
<varname>PGDATA
</varname>) of the relation.
27430 <entry role=
"func_table_entry"><para role=
"func_signature">
27432 <primary>pg_filenode_relation
</primary>
27434 <function>pg_filenode_relation
</function> (
<parameter>tablespace
</parameter> <type>oid
</type>,
<parameter>filenode
</parameter> <type>oid
</type> )
27435 <returnvalue>regclass
</returnvalue>
27438 Returns a relation's OID given the tablespace OID and filenode it is
27439 stored under. This is essentially the inverse mapping of
27440 <function>pg_relation_filepath
</function>. For a relation in the
27441 database's default tablespace, the tablespace can be specified as zero.
27442 Returns
<literal>NULL
</literal> if no relation in the current database
27443 is associated with the given values.
27451 <xref linkend=
"functions-admin-collation"/> lists functions used to manage
27455 <table id=
"functions-admin-collation">
27456 <title>Collation Management Functions
</title>
27460 <entry role=
"func_table_entry"><para role=
"func_signature">
27471 <entry role=
"func_table_entry"><para role=
"func_signature">
27473 <primary>pg_collation_actual_version
</primary>
27475 <function>pg_collation_actual_version
</function> (
<type>oid
</type> )
27476 <returnvalue>text
</returnvalue>
27479 Returns the actual version of the collation object as it is currently
27480 installed in the operating system. If this is different from the
27482 <structname>pg_collation
</structname>.
<structfield>collversion
</structfield>,
27483 then objects depending on the collation might need to be rebuilt. See
27484 also
<xref linkend=
"sql-altercollation"/>.
27489 <entry role=
"func_table_entry"><para role=
"func_signature">
27491 <primary>pg_database_collation_actual_version
</primary>
27493 <function>pg_database_collation_actual_version
</function> (
<type>oid
</type> )
27494 <returnvalue>text
</returnvalue>
27497 Returns the actual version of the database's collation as it is currently
27498 installed in the operating system. If this is different from the
27500 <structname>pg_database
</structname>.
<structfield>datcollversion
</structfield>,
27501 then objects depending on the collation might need to be rebuilt. See
27502 also
<xref linkend=
"sql-alterdatabase"/>.
27507 <entry role=
"func_table_entry"><para role=
"func_signature">
27509 <primary>pg_import_system_collations
</primary>
27511 <function>pg_import_system_collations
</function> (
<parameter>schema
</parameter> <type>regnamespace
</type> )
27512 <returnvalue>integer
</returnvalue>
27515 Adds collations to the system
27516 catalog
<structname>pg_collation
</structname> based on all the locales
27517 it finds in the operating system. This is
27518 what
<command>initdb
</command> uses; see
27519 <xref linkend=
"collation-managing"/> for more details. If additional
27520 locales are installed into the operating system later on, this
27521 function can be run again to add collations for the new locales.
27522 Locales that match existing entries
27523 in
<structname>pg_collation
</structname> will be skipped. (But
27524 collation objects based on locales that are no longer present in the
27525 operating system are not removed by this function.)
27526 The
<parameter>schema
</parameter> parameter would typically
27527 be
<literal>pg_catalog
</literal>, but that is not a requirement; the
27528 collations could be installed into some other schema as well. The
27529 function returns the number of new collation objects it created.
27530 Use of this function is restricted to superusers.
27538 <xref linkend=
"functions-info-partition"/> lists functions that provide
27539 information about the structure of partitioned tables.
27542 <table id=
"functions-info-partition">
27543 <title>Partitioning Information Functions
</title>
27547 <entry role=
"func_table_entry"><para role=
"func_signature">
27558 <entry role=
"func_table_entry"><para role=
"func_signature">
27560 <primary>pg_partition_tree
</primary>
27562 <function>pg_partition_tree
</function> (
<type>regclass
</type> )
27563 <returnvalue>setof record
</returnvalue>
27564 (
<parameter>relid
</parameter> <type>regclass
</type>,
27565 <parameter>parentrelid
</parameter> <type>regclass
</type>,
27566 <parameter>isleaf
</parameter> <type>boolean
</type>,
27567 <parameter>level
</parameter> <type>integer
</type> )
27570 Lists the tables or indexes in the partition tree of the
27571 given partitioned table or partitioned index, with one row for each
27572 partition. Information provided includes the OID of the partition,
27573 the OID of its immediate parent, a boolean value telling if the
27574 partition is a leaf, and an integer telling its level in the hierarchy.
27575 The level value is
0 for the input table or index,
1 for its
27576 immediate child partitions,
2 for their partitions, and so on.
27577 Returns no rows if the relation does not exist or is not a partition
27578 or partitioned table.
27583 <entry role=
"func_table_entry"><para role=
"func_signature">
27585 <primary>pg_partition_ancestors
</primary>
27587 <function>pg_partition_ancestors
</function> (
<type>regclass
</type> )
27588 <returnvalue>setof regclass
</returnvalue>
27591 Lists the ancestor relations of the given partition,
27592 including the relation itself. Returns no rows if the relation
27593 does not exist or is not a partition or partitioned table.
27598 <entry role=
"func_table_entry"><para role=
"func_signature">
27600 <primary>pg_partition_root
</primary>
27602 <function>pg_partition_root
</function> (
<type>regclass
</type> )
27603 <returnvalue>regclass
</returnvalue>
27606 Returns the top-most parent of the partition tree to which the given
27607 relation belongs. Returns
<literal>NULL
</literal> if the relation
27608 does not exist or is not a partition or partitioned table.
27616 For example, to check the total size of the data contained in a
27617 partitioned table
<structname>measurement
</structname>, one could use the
27620 SELECT pg_size_pretty(sum(pg_relation_size(relid))) AS total_size
27621 FROM pg_partition_tree('measurement');
27627 <sect2 id=
"functions-admin-index">
27628 <title>Index Maintenance Functions
</title>
27631 <xref linkend=
"functions-admin-index-table"/> shows the functions
27632 available for index maintenance tasks. (Note that these maintenance
27633 tasks are normally done automatically by autovacuum; use of these
27634 functions is only required in special cases.)
27635 These functions cannot be executed during recovery.
27636 Use of these functions is restricted to superusers and the owner
27637 of the given index.
27640 <table id=
"functions-admin-index-table">
27641 <title>Index Maintenance Functions
</title>
27645 <entry role=
"func_table_entry"><para role=
"func_signature">
27656 <entry role=
"func_table_entry"><para role=
"func_signature">
27658 <primary>brin_summarize_new_values
</primary>
27660 <function>brin_summarize_new_values
</function> (
<parameter>index
</parameter> <type>regclass
</type> )
27661 <returnvalue>integer
</returnvalue>
27664 Scans the specified BRIN index to find page ranges in the base table
27665 that are not currently summarized by the index; for any such range it
27666 creates a new summary index tuple by scanning those table pages.
27667 Returns the number of new page range summaries that were inserted
27673 <entry role=
"func_table_entry"><para role=
"func_signature">
27675 <primary>brin_summarize_range
</primary>
27677 <function>brin_summarize_range
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>blockNumber
</parameter> <type>bigint
</type> )
27678 <returnvalue>integer
</returnvalue>
27681 Summarizes the page range covering the given block, if not already
27682 summarized. This is
27683 like
<function>brin_summarize_new_values
</function> except that it
27684 only processes the page range that covers the given table block number.
27689 <entry role=
"func_table_entry"><para role=
"func_signature">
27691 <primary>brin_desummarize_range
</primary>
27693 <function>brin_desummarize_range
</function> (
<parameter>index
</parameter> <type>regclass
</type>,
<parameter>blockNumber
</parameter> <type>bigint
</type> )
27694 <returnvalue>void
</returnvalue>
27697 Removes the BRIN index tuple that summarizes the page range covering
27698 the given table block, if there is one.
27703 <entry role=
"func_table_entry"><para role=
"func_signature">
27705 <primary>gin_clean_pending_list
</primary>
27707 <function>gin_clean_pending_list
</function> (
<parameter>index
</parameter> <type>regclass
</type> )
27708 <returnvalue>bigint
</returnvalue>
27711 Cleans up the
<quote>pending
</quote> list of the specified GIN index
27712 by moving entries in it, in bulk, to the main GIN data structure.
27713 Returns the number of pages removed from the pending list.
27714 If the argument is a GIN index built with
27715 the
<literal>fastupdate
</literal> option disabled, no cleanup happens
27716 and the result is zero, because the index doesn't have a pending list.
27717 See
<xref linkend=
"gin-fast-update"/> and
<xref linkend=
"gin-tips"/>
27718 for details about the pending list and
<literal>fastupdate
</literal>
27728 <sect2 id=
"functions-admin-genfile">
27729 <title>Generic File Access Functions
</title>
27732 The functions shown in
<xref
27733 linkend=
"functions-admin-genfile-table"/> provide native access to
27734 files on the machine hosting the server. Only files within the
27735 database cluster directory and the
<varname>log_directory
</varname> can be
27736 accessed, unless the user is a superuser or is granted the role
27737 <literal>pg_read_server_files
</literal>. Use a relative path for files in
27738 the cluster directory, and a path matching the
<varname>log_directory
</varname>
27739 configuration setting for log files.
27743 Note that granting users the EXECUTE privilege on
27744 <function>pg_read_file()
</function>, or related functions, allows them the
27745 ability to read any file on the server that the database server process can
27746 read; these functions bypass all in-database privilege checks. This means
27747 that, for example, a user with such access is able to read the contents of
27748 the
<structname>pg_authid
</structname> table where authentication
27749 information is stored, as well as read any table data in the database.
27750 Therefore, granting access to these functions should be carefully
27755 When granting privilege on these functions, note that the table entries
27756 showing optional parameters are mostly implemented as several physical
27757 functions with different parameter lists. Privilege must be granted
27758 separately on each such function, if it is to be
27759 used.
<application>psql
</application>'s
<command>\df
</command> command
27760 can be useful to check what the actual function signatures are.
27764 Some of these functions take an optional
<parameter>missing_ok
</parameter>
27765 parameter, which specifies the behavior when the file or directory does
27766 not exist. If
<literal>true
</literal>, the function
27767 returns
<literal>NULL
</literal> or an empty result set, as appropriate.
27768 If
<literal>false
</literal>, an error is raised. (Failure conditions
27769 other than
<quote>file not found
</quote> are reported as errors in any
27770 case.) The default is
<literal>false
</literal>.
27773 <table id=
"functions-admin-genfile-table">
27774 <title>Generic File Access Functions
</title>
27778 <entry role=
"func_table_entry"><para role=
"func_signature">
27789 <entry role=
"func_table_entry"><para role=
"func_signature">
27791 <primary>pg_ls_dir
</primary>
27793 <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> )
27794 <returnvalue>setof text
</returnvalue>
27797 Returns the names of all files (and directories and other special
27798 files) in the specified
27799 directory. The
<parameter>include_dot_dirs
</parameter> parameter
27800 indicates whether
<quote>.
</quote> and
<quote>..
</quote> are to be
27801 included in the result set; the default is to exclude them. Including
27802 them can be useful when
<parameter>missing_ok
</parameter>
27803 is
<literal>true
</literal>, to distinguish an empty directory from a
27804 non-existent directory.
27807 This function is restricted to superusers by default, but other users
27808 can be granted EXECUTE to run the function.
27813 <entry role=
"func_table_entry"><para role=
"func_signature">
27815 <primary>pg_ls_logdir
</primary>
27817 <function>pg_ls_logdir
</function> ()
27818 <returnvalue>setof record
</returnvalue>
27819 (
<parameter>name
</parameter> <type>text
</type>,
27820 <parameter>size
</parameter> <type>bigint
</type>,
27821 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
27824 Returns the name, size, and last modification time (mtime) of each
27825 ordinary file in the server's log directory. Filenames beginning with
27826 a dot, directories, and other special files are excluded.
27829 This function is restricted to superusers and roles with privileges of
27830 the
<literal>pg_monitor
</literal> role by default, but other users can
27831 be granted EXECUTE to run the function.
27836 <entry role=
"func_table_entry"><para role=
"func_signature">
27838 <primary>pg_ls_waldir
</primary>
27840 <function>pg_ls_waldir
</function> ()
27841 <returnvalue>setof record
</returnvalue>
27842 (
<parameter>name
</parameter> <type>text
</type>,
27843 <parameter>size
</parameter> <type>bigint
</type>,
27844 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
27847 Returns the name, size, and last modification time (mtime) of each
27848 ordinary file in the server's write-ahead log (WAL) directory.
27849 Filenames beginning with a dot, directories, and other special files
27853 This function is restricted to superusers and roles with privileges of
27854 the
<literal>pg_monitor
</literal> role by default, but other users can
27855 be granted EXECUTE to run the function.
27860 <entry role=
"func_table_entry"><para role=
"func_signature">
27862 <primary>pg_ls_logicalmapdir
</primary>
27864 <function>pg_ls_logicalmapdir
</function> ()
27865 <returnvalue>setof record
</returnvalue>
27866 (
<parameter>name
</parameter> <type>text
</type>,
27867 <parameter>size
</parameter> <type>bigint
</type>,
27868 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
27871 Returns the name, size, and last modification time (mtime) of each
27872 ordinary file in the server's
<filename>pg_logical/mappings
</filename>
27873 directory. Filenames beginning with a dot, directories, and other
27874 special files are excluded.
27877 This function is restricted to superusers and members of
27878 the
<literal>pg_monitor
</literal> role by default, but other users can
27879 be granted EXECUTE to run the function.
27884 <entry role=
"func_table_entry"><para role=
"func_signature">
27886 <primary>pg_ls_logicalsnapdir
</primary>
27888 <function>pg_ls_logicalsnapdir
</function> ()
27889 <returnvalue>setof record
</returnvalue>
27890 (
<parameter>name
</parameter> <type>text
</type>,
27891 <parameter>size
</parameter> <type>bigint
</type>,
27892 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
27895 Returns the name, size, and last modification time (mtime) of each
27896 ordinary file in the server's
<filename>pg_logical/snapshots
</filename>
27897 directory. Filenames beginning with a dot, directories, and other
27898 special files are excluded.
27901 This function is restricted to superusers and members of
27902 the
<literal>pg_monitor
</literal> role by default, but other users can
27903 be granted EXECUTE to run the function.
27908 <entry role=
"func_table_entry"><para role=
"func_signature">
27910 <primary>pg_ls_replslotdir
</primary>
27912 <function>pg_ls_replslotdir
</function> (
<parameter>slot_name
</parameter> <type>text
</type> )
27913 <returnvalue>setof record
</returnvalue>
27914 (
<parameter>name
</parameter> <type>text
</type>,
27915 <parameter>size
</parameter> <type>bigint
</type>,
27916 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
27919 Returns the name, size, and last modification time (mtime) of each
27920 ordinary file in the server's
<filename>pg_replslot/slot_name
</filename>
27921 directory, where
<parameter>slot_name
</parameter> is the name of the
27922 replication slot provided as input of the function. Filenames beginning
27923 with a dot, directories, and other special files are excluded.
27926 This function is restricted to superusers and members of
27927 the
<literal>pg_monitor
</literal> role by default, but other users can
27928 be granted EXECUTE to run the function.
27933 <entry role=
"func_table_entry"><para role=
"func_signature">
27935 <primary>pg_ls_archive_statusdir
</primary>
27937 <function>pg_ls_archive_statusdir
</function> ()
27938 <returnvalue>setof record
</returnvalue>
27939 (
<parameter>name
</parameter> <type>text
</type>,
27940 <parameter>size
</parameter> <type>bigint
</type>,
27941 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
27944 Returns the name, size, and last modification time (mtime) of each
27945 ordinary file in the server's WAL archive status directory
27946 (
<filename>pg_wal/archive_status
</filename>). Filenames beginning
27947 with a dot, directories, and other special files are excluded.
27950 This function is restricted to superusers and members of
27951 the
<literal>pg_monitor
</literal> role by default, but other users can
27952 be granted EXECUTE to run the function.
27957 <entry role=
"func_table_entry"><para role=
"func_signature">
27960 <primary>pg_ls_tmpdir
</primary>
27962 <function>pg_ls_tmpdir
</function> (
<optional> <parameter>tablespace
</parameter> <type>oid
</type> </optional> )
27963 <returnvalue>setof record
</returnvalue>
27964 (
<parameter>name
</parameter> <type>text
</type>,
27965 <parameter>size
</parameter> <type>bigint
</type>,
27966 <parameter>modification
</parameter> <type>timestamp with time zone
</type> )
27969 Returns the name, size, and last modification time (mtime) of each
27970 ordinary file in the temporary file directory for the
27971 specified
<parameter>tablespace
</parameter>.
27972 If
<parameter>tablespace
</parameter> is not provided,
27973 the
<literal>pg_default
</literal> tablespace is examined. Filenames
27974 beginning with a dot, directories, and other special files are
27978 This function is restricted to superusers and members of
27979 the
<literal>pg_monitor
</literal> role by default, but other users can
27980 be granted EXECUTE to run the function.
27985 <entry role=
"func_table_entry"><para role=
"func_signature">
27987 <primary>pg_read_file
</primary>
27989 <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> )
27990 <returnvalue>text
</returnvalue>
27993 Returns all or part of a text file, starting at the
27994 given byte
<parameter>offset
</parameter>, returning at
27995 most
<parameter>length
</parameter> bytes (less if the end of file is
27996 reached first). If
<parameter>offset
</parameter> is negative, it is
27997 relative to the end of the file. If
<parameter>offset
</parameter>
27998 and
<parameter>length
</parameter> are omitted, the entire file is
27999 returned. The bytes read from the file are interpreted as a string in
28000 the database's encoding; an error is thrown if they are not valid in
28004 This function is restricted to superusers by default, but other users
28005 can be granted EXECUTE to run the function.
28010 <entry role=
"func_table_entry"><para role=
"func_signature">
28012 <primary>pg_read_binary_file
</primary>
28014 <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> )
28015 <returnvalue>bytea
</returnvalue>
28018 Returns all or part of a file. This function is identical to
28019 <function>pg_read_file
</function> except that it can read arbitrary
28020 binary data, returning the result as
<type>bytea
</type>
28021 not
<type>text
</type>; accordingly, no encoding checks are performed.
28024 This function is restricted to superusers by default, but other users
28025 can be granted EXECUTE to run the function.
28028 In combination with the
<function>convert_from
</function> function,
28029 this function can be used to read a text file in a specified encoding
28030 and convert to the database's encoding:
28032 SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
28038 <entry role=
"func_table_entry"><para role=
"func_signature">
28040 <primary>pg_stat_file
</primary>
28042 <function>pg_stat_file
</function> (
<parameter>filename
</parameter> <type>text
</type> <optional>,
<parameter>missing_ok
</parameter> <type>boolean
</type> </optional> )
28043 <returnvalue>record
</returnvalue>
28044 (
<parameter>size
</parameter> <type>bigint
</type>,
28045 <parameter>access
</parameter> <type>timestamp with time zone
</type>,
28046 <parameter>modification
</parameter> <type>timestamp with time zone
</type>,
28047 <parameter>change
</parameter> <type>timestamp with time zone
</type>,
28048 <parameter>creation
</parameter> <type>timestamp with time zone
</type>,
28049 <parameter>isdir
</parameter> <type>boolean
</type> )
28052 Returns a record containing the file's size, last access time stamp,
28053 last modification time stamp, last file status change time stamp (Unix
28054 platforms only), file creation time stamp (Windows only), and a flag
28055 indicating if it is a directory.
28058 This function is restricted to superusers by default, but other users
28059 can be granted EXECUTE to run the function.
28069 <sect2 id=
"functions-advisory-locks">
28070 <title>Advisory Lock Functions
</title>
28073 The functions shown in
<xref linkend=
"functions-advisory-locks-table"/>
28074 manage advisory locks. For details about proper use of these functions,
28075 see
<xref linkend=
"advisory-locks"/>.
28079 All these functions are intended to be used to lock application-defined
28080 resources, which can be identified either by a single
64-bit key value or
28081 two
32-bit key values (note that these two key spaces do not overlap).
28082 If another session already holds a conflicting lock on the same resource
28083 identifier, the functions will either wait until the resource becomes
28084 available, or return a
<literal>false
</literal> result, as appropriate for
28086 Locks can be either shared or exclusive: a shared lock does not conflict
28087 with other shared locks on the same resource, only with exclusive locks.
28088 Locks can be taken at session level (so that they are held until released
28089 or the session ends) or at transaction level (so that they are held until
28090 the current transaction ends; there is no provision for manual release).
28091 Multiple session-level lock requests stack, so that if the same resource
28092 identifier is locked three times there must then be three unlock requests
28093 to release the resource in advance of session end.
28096 <table id=
"functions-advisory-locks-table">
28097 <title>Advisory Lock Functions
</title>
28101 <entry role=
"func_table_entry"><para role=
"func_signature">
28112 <entry role=
"func_table_entry"><para role=
"func_signature">
28114 <primary>pg_advisory_lock
</primary>
28116 <function>pg_advisory_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28117 <returnvalue>void
</returnvalue>
28119 <para role=
"func_signature">
28120 <function>pg_advisory_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28121 <returnvalue>void
</returnvalue>
28124 Obtains an exclusive session-level advisory lock, waiting if necessary.
28129 <entry role=
"func_table_entry"><para role=
"func_signature">
28131 <primary>pg_advisory_lock_shared
</primary>
28133 <function>pg_advisory_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28134 <returnvalue>void
</returnvalue>
28136 <para role=
"func_signature">
28137 <function>pg_advisory_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28138 <returnvalue>void
</returnvalue>
28141 Obtains a shared session-level advisory lock, waiting if necessary.
28146 <entry role=
"func_table_entry"><para role=
"func_signature">
28148 <primary>pg_advisory_unlock
</primary>
28150 <function>pg_advisory_unlock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28151 <returnvalue>boolean
</returnvalue>
28153 <para role=
"func_signature">
28154 <function>pg_advisory_unlock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28155 <returnvalue>boolean
</returnvalue>
28158 Releases a previously-acquired exclusive session-level advisory lock.
28159 Returns
<literal>true
</literal> if the lock is successfully released.
28160 If the lock was not held,
<literal>false
</literal> is returned, and in
28161 addition, an SQL warning will be reported by the server.
28166 <entry role=
"func_table_entry"><para role=
"func_signature">
28168 <primary>pg_advisory_unlock_all
</primary>
28170 <function>pg_advisory_unlock_all
</function> ()
28171 <returnvalue>void
</returnvalue>
28174 Releases all session-level advisory locks held by the current session.
28175 (This function is implicitly invoked at session end, even if the
28176 client disconnects ungracefully.)
28181 <entry role=
"func_table_entry"><para role=
"func_signature">
28183 <primary>pg_advisory_unlock_shared
</primary>
28185 <function>pg_advisory_unlock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28186 <returnvalue>boolean
</returnvalue>
28188 <para role=
"func_signature">
28189 <function>pg_advisory_unlock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28190 <returnvalue>boolean
</returnvalue>
28193 Releases a previously-acquired shared session-level advisory lock.
28194 Returns
<literal>true
</literal> if the lock is successfully released.
28195 If the lock was not held,
<literal>false
</literal> is returned, and in
28196 addition, an SQL warning will be reported by the server.
28201 <entry role=
"func_table_entry"><para role=
"func_signature">
28203 <primary>pg_advisory_xact_lock
</primary>
28205 <function>pg_advisory_xact_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28206 <returnvalue>void
</returnvalue>
28208 <para role=
"func_signature">
28209 <function>pg_advisory_xact_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28210 <returnvalue>void
</returnvalue>
28213 Obtains an exclusive transaction-level advisory lock, waiting if
28219 <entry role=
"func_table_entry"><para role=
"func_signature">
28221 <primary>pg_advisory_xact_lock_shared
</primary>
28223 <function>pg_advisory_xact_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28224 <returnvalue>void
</returnvalue>
28226 <para role=
"func_signature">
28227 <function>pg_advisory_xact_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28228 <returnvalue>void
</returnvalue>
28231 Obtains a shared transaction-level advisory lock, waiting if
28237 <entry role=
"func_table_entry"><para role=
"func_signature">
28239 <primary>pg_try_advisory_lock
</primary>
28241 <function>pg_try_advisory_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28242 <returnvalue>boolean
</returnvalue>
28244 <para role=
"func_signature">
28245 <function>pg_try_advisory_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28246 <returnvalue>boolean
</returnvalue>
28249 Obtains an exclusive session-level advisory lock if available.
28250 This will either obtain the lock immediately and
28251 return
<literal>true
</literal>, or return
<literal>false
</literal>
28252 without waiting if the lock cannot be acquired immediately.
28257 <entry role=
"func_table_entry"><para role=
"func_signature">
28259 <primary>pg_try_advisory_lock_shared
</primary>
28261 <function>pg_try_advisory_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28262 <returnvalue>boolean
</returnvalue>
28264 <para role=
"func_signature">
28265 <function>pg_try_advisory_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28266 <returnvalue>boolean
</returnvalue>
28269 Obtains a shared session-level advisory lock if available.
28270 This will either obtain the lock immediately and
28271 return
<literal>true
</literal>, or return
<literal>false
</literal>
28272 without waiting if the lock cannot be acquired immediately.
28277 <entry role=
"func_table_entry"><para role=
"func_signature">
28279 <primary>pg_try_advisory_xact_lock
</primary>
28281 <function>pg_try_advisory_xact_lock
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28282 <returnvalue>boolean
</returnvalue>
28284 <para role=
"func_signature">
28285 <function>pg_try_advisory_xact_lock
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28286 <returnvalue>boolean
</returnvalue>
28289 Obtains an exclusive transaction-level advisory lock if available.
28290 This will either obtain the lock immediately and
28291 return
<literal>true
</literal>, or return
<literal>false
</literal>
28292 without waiting if the lock cannot be acquired immediately.
28297 <entry role=
"func_table_entry"><para role=
"func_signature">
28299 <primary>pg_try_advisory_xact_lock_shared
</primary>
28301 <function>pg_try_advisory_xact_lock_shared
</function> (
<parameter>key
</parameter> <type>bigint
</type> )
28302 <returnvalue>boolean
</returnvalue>
28304 <para role=
"func_signature">
28305 <function>pg_try_advisory_xact_lock_shared
</function> (
<parameter>key1
</parameter> <type>integer
</type>,
<parameter>key2
</parameter> <type>integer
</type> )
28306 <returnvalue>boolean
</returnvalue>
28309 Obtains a shared transaction-level advisory lock if available.
28310 This will either obtain the lock immediately and
28311 return
<literal>true
</literal>, or return
<literal>false
</literal>
28312 without waiting if the lock cannot be acquired immediately.
28323 <sect1 id=
"functions-trigger">
28324 <title>Trigger Functions
</title>
28327 While many uses of triggers involve user-written trigger functions,
28328 <productname>PostgreSQL
</productname> provides a few built-in trigger
28329 functions that can be used directly in user-defined triggers. These
28330 are summarized in
<xref linkend=
"builtin-triggers-table"/>.
28331 (Additional built-in trigger functions exist, which implement foreign
28332 key constraints and deferred index constraints. Those are not documented
28333 here since users need not use them directly.)
28337 For more information about creating triggers, see
28338 <xref linkend=
"sql-createtrigger"/>.
28341 <table id=
"builtin-triggers-table">
28342 <title>Built-In Trigger Functions
</title>
28346 <entry role=
"func_table_entry"><para role=
"func_signature">
28360 <entry role=
"func_table_entry"><para role=
"func_signature">
28362 <primary>suppress_redundant_updates_trigger
</primary>
28364 <function>suppress_redundant_updates_trigger
</function> ( )
28365 <returnvalue>trigger
</returnvalue>
28368 Suppresses do-nothing update operations. See below for details.
28371 <literal>CREATE TRIGGER ... suppress_redundant_updates_trigger()
</literal>
28376 <entry role=
"func_table_entry"><para role=
"func_signature">
28378 <primary>tsvector_update_trigger
</primary>
28380 <function>tsvector_update_trigger
</function> ( )
28381 <returnvalue>trigger
</returnvalue>
28384 Automatically updates a
<type>tsvector
</type> column from associated
28385 plain-text document column(s). The text search configuration to use
28386 is specified by name as a trigger argument. See
28387 <xref linkend=
"textsearch-update-triggers"/> for details.
28390 <literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)
</literal>
28395 <entry role=
"func_table_entry"><para role=
"func_signature">
28397 <primary>tsvector_update_trigger_column
</primary>
28399 <function>tsvector_update_trigger_column
</function> ( )
28400 <returnvalue>trigger
</returnvalue>
28403 Automatically updates a
<type>tsvector
</type> column from associated
28404 plain-text document column(s). The text search configuration to use
28405 is taken from a
<type>regconfig
</type> column of the table. See
28406 <xref linkend=
"textsearch-update-triggers"/> for details.
28409 <literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, tsconfigcol, title, body)
</literal>
28417 The
<function>suppress_redundant_updates_trigger
</function> function,
28418 when applied as a row-level
<literal>BEFORE UPDATE
</literal> trigger,
28419 will prevent any update that does not actually change the data in the
28420 row from taking place. This overrides the normal behavior which always
28421 performs a physical row update
28422 regardless of whether or not the data has changed. (This normal behavior
28423 makes updates run faster, since no checking is required, and is also
28424 useful in certain cases.)
28428 Ideally, you should avoid running updates that don't actually
28429 change the data in the record. Redundant updates can cost considerable
28430 unnecessary time, especially if there are lots of indexes to alter,
28431 and space in dead rows that will eventually have to be vacuumed.
28432 However, detecting such situations in client code is not
28433 always easy, or even possible, and writing expressions to detect
28434 them can be error-prone. An alternative is to use
28435 <function>suppress_redundant_updates_trigger
</function>, which will skip
28436 updates that don't change the data. You should use this with care,
28437 however. The trigger takes a small but non-trivial time for each record,
28438 so if most of the records affected by updates do actually change,
28439 use of this trigger will make updates run slower on average.
28443 The
<function>suppress_redundant_updates_trigger
</function> function can be
28444 added to a table like this:
28446 CREATE TRIGGER z_min_update
28447 BEFORE UPDATE ON tablename
28448 FOR EACH ROW EXECUTE FUNCTION suppress_redundant_updates_trigger();
28450 In most cases, you need to fire this trigger last for each row, so that
28451 it does not override other triggers that might wish to alter the row.
28452 Bearing in mind that triggers fire in name order, you would therefore
28453 choose a trigger name that comes after the name of any other trigger
28454 you might have on the table. (Hence the
<quote>z
</quote> prefix in the
28459 <sect1 id=
"functions-event-triggers">
28460 <title>Event Trigger Functions
</title>
28463 <productname>PostgreSQL
</productname> provides these helper functions
28464 to retrieve information from event triggers.
28468 For more information about event triggers,
28469 see
<xref linkend=
"event-triggers"/>.
28472 <sect2 id=
"pg-event-trigger-ddl-command-end-functions">
28473 <title>Capturing Changes at Command End
</title>
28476 <primary>pg_event_trigger_ddl_commands
</primary>
28480 <function>pg_event_trigger_ddl_commands
</function> ()
<returnvalue>setof record
</returnvalue>
28484 <function>pg_event_trigger_ddl_commands
</function> returns a list of
28485 <acronym>DDL
</acronym> commands executed by each user action,
28486 when invoked in a function attached to a
28487 <literal>ddl_command_end
</literal> event trigger. If called in any other
28488 context, an error is raised.
28489 <function>pg_event_trigger_ddl_commands
</function> returns one row for each
28490 base command executed; some commands that are a single SQL sentence
28491 may return more than one row. This function returns the following
28498 <entry>Name
</entry>
28499 <entry>Type
</entry>
28500 <entry>Description
</entry>
28506 <entry><literal>classid
</literal></entry>
28507 <entry><type>oid
</type></entry>
28508 <entry>OID of catalog the object belongs in
</entry>
28511 <entry><literal>objid
</literal></entry>
28512 <entry><type>oid
</type></entry>
28513 <entry>OID of the object itself
</entry>
28516 <entry><literal>objsubid
</literal></entry>
28517 <entry><type>integer
</type></entry>
28518 <entry>Sub-object ID (e.g., attribute number for a column)
</entry>
28521 <entry><literal>command_tag
</literal></entry>
28522 <entry><type>text
</type></entry>
28523 <entry>Command tag
</entry>
28526 <entry><literal>object_type
</literal></entry>
28527 <entry><type>text
</type></entry>
28528 <entry>Type of the object
</entry>
28531 <entry><literal>schema_name
</literal></entry>
28532 <entry><type>text
</type></entry>
28534 Name of the schema the object belongs in, if any; otherwise
<literal>NULL
</literal>.
28535 No quoting is applied.
28539 <entry><literal>object_identity
</literal></entry>
28540 <entry><type>text
</type></entry>
28542 Text rendering of the object identity, schema-qualified. Each
28543 identifier included in the identity is quoted if necessary.
28547 <entry><literal>in_extension
</literal></entry>
28548 <entry><type>boolean
</type></entry>
28549 <entry>True if the command is part of an extension script
</entry>
28552 <entry><literal>command
</literal></entry>
28553 <entry><type>pg_ddl_command
</type></entry>
28555 A complete representation of the command, in internal format.
28556 This cannot be output directly, but it can be passed to other
28557 functions to obtain different pieces of information about the
28567 <sect2 id=
"pg-event-trigger-sql-drop-functions">
28568 <title>Processing Objects Dropped by a DDL Command
</title>
28571 <primary>pg_event_trigger_dropped_objects
</primary>
28575 <function>pg_event_trigger_dropped_objects
</function> ()
<returnvalue>setof record
</returnvalue>
28579 <function>pg_event_trigger_dropped_objects
</function> returns a list of all objects
28580 dropped by the command in whose
<literal>sql_drop
</literal> event it is called.
28581 If called in any other context, an error is raised.
28582 This function returns the following columns:
28588 <entry>Name
</entry>
28589 <entry>Type
</entry>
28590 <entry>Description
</entry>
28596 <entry><literal>classid
</literal></entry>
28597 <entry><type>oid
</type></entry>
28598 <entry>OID of catalog the object belonged in
</entry>
28601 <entry><literal>objid
</literal></entry>
28602 <entry><type>oid
</type></entry>
28603 <entry>OID of the object itself
</entry>
28606 <entry><literal>objsubid
</literal></entry>
28607 <entry><type>integer
</type></entry>
28608 <entry>Sub-object ID (e.g., attribute number for a column)
</entry>
28611 <entry><literal>original
</literal></entry>
28612 <entry><type>boolean
</type></entry>
28613 <entry>True if this was one of the root object(s) of the deletion
</entry>
28616 <entry><literal>normal
</literal></entry>
28617 <entry><type>boolean
</type></entry>
28619 True if there was a normal dependency relationship
28620 in the dependency graph leading to this object
28624 <entry><literal>is_temporary
</literal></entry>
28625 <entry><type>boolean
</type></entry>
28627 True if this was a temporary object
28631 <entry><literal>object_type
</literal></entry>
28632 <entry><type>text
</type></entry>
28633 <entry>Type of the object
</entry>
28636 <entry><literal>schema_name
</literal></entry>
28637 <entry><type>text
</type></entry>
28639 Name of the schema the object belonged in, if any; otherwise
<literal>NULL
</literal>.
28640 No quoting is applied.
28644 <entry><literal>object_name
</literal></entry>
28645 <entry><type>text
</type></entry>
28647 Name of the object, if the combination of schema and name can be
28648 used as a unique identifier for the object; otherwise
<literal>NULL
</literal>.
28649 No quoting is applied, and name is never schema-qualified.
28653 <entry><literal>object_identity
</literal></entry>
28654 <entry><type>text
</type></entry>
28656 Text rendering of the object identity, schema-qualified. Each
28657 identifier included in the identity is quoted if necessary.
28661 <entry><literal>address_names
</literal></entry>
28662 <entry><type>text[]
</type></entry>
28664 An array that, together with
<literal>object_type
</literal> and
28665 <literal>address_args
</literal>, can be used by
28666 the
<function>pg_get_object_address
</function> function to
28667 recreate the object address in a remote server containing an
28668 identically named object of the same kind.
28672 <entry><literal>address_args
</literal></entry>
28673 <entry><type>text[]
</type></entry>
28675 Complement for
<literal>address_names
</literal>
28684 The
<function>pg_event_trigger_dropped_objects
</function> function can be used
28685 in an event trigger like this:
28687 CREATE FUNCTION test_event_trigger_for_drops()
28688 RETURNS event_trigger LANGUAGE plpgsql AS $$
28692 FOR obj IN SELECT * FROM pg_event_trigger_dropped_objects()
28694 RAISE NOTICE '% dropped object: % %.% %',
28699 obj.object_identity;
28703 CREATE EVENT TRIGGER test_event_trigger_for_drops
28705 EXECUTE FUNCTION test_event_trigger_for_drops();
28710 <sect2 id=
"pg-event-trigger-table-rewrite-functions">
28711 <title>Handling a Table Rewrite Event
</title>
28714 The functions shown in
28715 <xref linkend=
"functions-event-trigger-table-rewrite"/>
28716 provide information about a table for which a
28717 <literal>table_rewrite
</literal> event has just been called.
28718 If called in any other context, an error is raised.
28721 <table id=
"functions-event-trigger-table-rewrite">
28722 <title>Table Rewrite Information Functions
</title>
28726 <entry role=
"func_table_entry"><para role=
"func_signature">
28737 <entry role=
"func_table_entry"><para role=
"func_signature">
28739 <primary>pg_event_trigger_table_rewrite_oid
</primary>
28741 <function>pg_event_trigger_table_rewrite_oid
</function> ()
28742 <returnvalue>oid
</returnvalue>
28745 Returns the OID of the table about to be rewritten.
28750 <entry role=
"func_table_entry"><para role=
"func_signature">
28752 <primary>pg_event_trigger_table_rewrite_reason
</primary>
28754 <function>pg_event_trigger_table_rewrite_reason
</function> ()
28755 <returnvalue>integer
</returnvalue>
28758 Returns a code explaining the reason(s) for rewriting. The exact
28759 meaning of the codes is release dependent.
28767 These functions can be used in an event trigger like this:
28769 CREATE FUNCTION test_event_trigger_table_rewrite_oid()
28770 RETURNS event_trigger
28771 LANGUAGE plpgsql AS
28774 RAISE NOTICE 'rewriting table % for reason %',
28775 pg_event_trigger_table_rewrite_oid()::regclass,
28776 pg_event_trigger_table_rewrite_reason();
28780 CREATE EVENT TRIGGER test_table_rewrite_oid
28782 EXECUTE FUNCTION test_event_trigger_table_rewrite_oid();
28788 <sect1 id=
"functions-statistics">
28789 <title>Statistics Information Functions
</title>
28791 <indexterm zone=
"functions-statistics">
28792 <primary>function
</primary>
28793 <secondary>statistics
</secondary>
28797 <productname>PostgreSQL
</productname> provides a function to inspect complex
28798 statistics defined using the
<command>CREATE STATISTICS
</command> command.
28801 <sect2 id=
"functions-statistics-mcv">
28802 <title>Inspecting MCV Lists
</title>
28805 <primary>pg_mcv_list_items
</primary>
28809 <function>pg_mcv_list_items
</function> (
<type>pg_mcv_list
</type> )
<returnvalue>setof record
</returnvalue>
28813 <function>pg_mcv_list_items
</function> returns a set of records describing
28814 all items stored in a multi-column
<acronym>MCV
</acronym> list. It
28815 returns the following columns:
28821 <entry>Name
</entry>
28822 <entry>Type
</entry>
28823 <entry>Description
</entry>
28829 <entry><literal>index
</literal></entry>
28830 <entry><type>integer
</type></entry>
28831 <entry>index of the item in the
<acronym>MCV
</acronym> list
</entry>
28834 <entry><literal>values
</literal></entry>
28835 <entry><type>text[]
</type></entry>
28836 <entry>values stored in the MCV item
</entry>
28839 <entry><literal>nulls
</literal></entry>
28840 <entry><type>boolean[]
</type></entry>
28841 <entry>flags identifying
<literal>NULL
</literal> values
</entry>
28844 <entry><literal>frequency
</literal></entry>
28845 <entry><type>double precision
</type></entry>
28846 <entry>frequency of this
<acronym>MCV
</acronym> item
</entry>
28849 <entry><literal>base_frequency
</literal></entry>
28850 <entry><type>double precision
</type></entry>
28851 <entry>base frequency of this
<acronym>MCV
</acronym> item
</entry>
28859 The
<function>pg_mcv_list_items
</function> function can be used like this:
28862 SELECT m.* FROM pg_statistic_ext join pg_statistic_ext_data on (oid = stxoid),
28863 pg_mcv_list_items(stxdmcv) m WHERE stxname = 'stts';
28866 Values of the
<type>pg_mcv_list
</type> type can be obtained only from the
28867 <structname>pg_statistic_ext_data
</structname>.
<structfield>stxdmcv
</structfield>