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. Users can also
17 define their own functions and operators, as described in
18 <xref linkend=
"server-programming">. The
19 <application>psql
</application> commands
<command>\df
</command> and
20 <command>\do
</command> can be used to list all
21 available functions and operators, respectively.
25 If you are concerned about portability then note that most of
26 the functions and operators described in this chapter, with the
27 exception of the most trivial arithmetic and comparison operators
28 and some explicitly marked functions, are not specified by the
29 <acronym>SQL
</acronym> standard. Some of this extended functionality
30 is present in other
<acronym>SQL
</acronym> database management
31 systems, and in many cases this functionality is compatible and
32 consistent between the various implementations. This chapter is also
33 not exhaustive; additional functions appear in relevant sections of
38 <sect1 id=
"functions-logical">
39 <title>Logical Operators
</title>
41 <indexterm zone=
"functions-logical">
42 <primary>operator
</primary>
43 <secondary>logical
</secondary>
47 <primary>Boolean
</primary>
48 <secondary>operators
</secondary>
49 <see>operators, logical
</see>
53 The usual logical operators are available:
56 <primary>AND (operator)
</primary>
60 <primary>OR (operator)
</primary>
64 <primary>NOT (operator)
</primary>
68 <primary>conjunction
</primary>
72 <primary>disjunction
</primary>
76 <primary>negation
</primary>
80 <member><literal>AND<
/></member>
81 <member><literal>OR<
/></member>
82 <member><literal>NOT<
/></member>
85 <acronym>SQL
</acronym> uses a three-valued Boolean logic where the null value represents
86 <quote>unknown
</quote>. Observe the following truth tables:
92 <entry><replaceable>a
</replaceable></entry>
93 <entry><replaceable>b
</replaceable></entry>
94 <entry><replaceable>a
</replaceable> AND
<replaceable>b
</replaceable></entry>
95 <entry><replaceable>a
</replaceable> OR
<replaceable>b
</replaceable></entry>
149 <entry><replaceable>a
</replaceable></entry>
150 <entry>NOT
<replaceable>a
</replaceable></entry>
175 The operators
<literal>AND
</literal> and
<literal>OR
</literal> are
176 commutative, that is, you can switch the left and right operand
177 without affecting the result. But see
<xref
178 linkend=
"syntax-express-eval"> for more information about the
179 order of evaluation of subexpressions.
183 <sect1 id=
"functions-comparison">
184 <title>Comparison Operators
</title>
186 <indexterm zone=
"functions-comparison">
187 <primary>comparison
</primary>
188 <secondary>operators
</secondary>
192 The usual comparison operators are available, shown in
<xref
193 linkend=
"functions-comparison-table">.
196 <table id=
"functions-comparison-table">
197 <title>Comparison Operators
</title>
201 <entry>Operator
</entry>
202 <entry>Description
</entry>
208 <entry> <literal><</literal> </entry>
209 <entry>less than
</entry>
213 <entry> <literal>></literal> </entry>
214 <entry>greater than
</entry>
218 <entry> <literal><=
</literal> </entry>
219 <entry>less than or equal to
</entry>
223 <entry> <literal>>=
</literal> </entry>
224 <entry>greater than or equal to
</entry>
228 <entry> <literal>=
</literal> </entry>
233 <entry> <literal><></literal> or
<literal>!=
</literal> </entry>
234 <entry>not equal
</entry>
242 The
<literal>!=
</literal> operator is converted to
243 <literal><></literal> in the parser stage. It is not
244 possible to implement
<literal>!=
</literal> and
245 <literal><></literal> operators that do different things.
250 Comparison operators are available for all relevant data types.
251 All comparison operators are binary operators that
252 return values of type
<type>boolean
</type>; expressions like
253 <literal>1 < 2 < 3</literal> are not valid (because there is
254 no
<literal><</literal> operator to compare a Boolean value with
255 <literal>3</literal>).
260 <primary>BETWEEN
</primary>
262 In addition to the comparison operators, the special
263 <token>BETWEEN
</token> construct is available:
265 <replaceable>a
</replaceable> BETWEEN
<replaceable>x
</replaceable> AND
<replaceable>y
</replaceable>
269 <replaceable>a
</replaceable> >=
<replaceable>x
</replaceable> AND
<replaceable>a
</replaceable> <=
<replaceable>y
</replaceable>
271 Notice that
<token>BETWEEN
</token> treats the endpoint values as included
273 <literal>NOT BETWEEN
</literal> does the opposite comparison:
275 <replaceable>a
</replaceable> NOT BETWEEN
<replaceable>x
</replaceable> AND
<replaceable>y
</replaceable>
279 <replaceable>a
</replaceable> < <replaceable>x
</replaceable> OR
<replaceable>a
</replaceable> > <replaceable>y
</replaceable>
282 <primary>BETWEEN SYMMETRIC
</primary>
284 <literal>BETWEEN SYMMETRIC<
/> is the same as
<literal>BETWEEN<
/>
285 except there is no requirement that the argument to the left of
286 <literal>AND<
/> be less than or equal to the argument on the right.
287 If it is not, those two arguments are automatically swapped, so that
288 a nonempty range is always implied.
293 <primary>IS NULL
</primary>
296 <primary>IS NOT NULL
</primary>
299 <primary>ISNULL
</primary>
302 <primary>NOTNULL
</primary>
304 To check whether a value is or is not null, use the constructs:
306 <replaceable>expression
</replaceable> IS NULL
307 <replaceable>expression
</replaceable> IS NOT NULL
309 or the equivalent, but nonstandard, constructs:
311 <replaceable>expression
</replaceable> ISNULL
312 <replaceable>expression
</replaceable> NOTNULL
314 <indexterm><primary>null value
</primary><secondary>comparing
</secondary></indexterm>
318 Do
<emphasis>not
</emphasis> write
319 <literal><replaceable>expression
</replaceable> = NULL
</literal>
320 because
<literal>NULL<
/> is not
<quote>equal to
</quote>
321 <literal>NULL<
/>. (The null value represents an unknown value,
322 and it is not known whether two unknown values are equal.) This
323 behavior conforms to the SQL standard.
328 Some applications might expect that
329 <literal><replaceable>expression
</replaceable> = NULL
</literal>
330 returns true if
<replaceable>expression
</replaceable> evaluates to
331 the null value. It is highly recommended that these applications
332 be modified to comply with the SQL standard. However, if that
333 cannot be done the
<xref linkend=
"guc-transform-null-equals">
334 configuration variable is available. If it is enabled,
335 <productname>PostgreSQL
</productname> will convert
<literal>x =
336 NULL
</literal> clauses to
<literal>x IS NULL
</literal>.
342 If the
<replaceable>expression
</replaceable> is row-valued, then
343 <literal>IS NULL<
/> is true when the row expression itself is null
344 or when all the row's fields are null, while
345 <literal>IS NOT NULL<
/> is true when the row expression itself is non-null
346 and all the row's fields are non-null. Because of this behavior,
347 <literal>IS NULL<
/> and
<literal>IS NOT NULL<
/> do not always return
348 inverse results for row-valued expressions, i.e., a row-valued
349 expression that contains both NULL and non-null values will return false
351 This definition conforms to the SQL standard, and is a change from the
352 inconsistent behavior exhibited by
<productname>PostgreSQL
</productname>
353 versions prior to
8.2.
359 <primary>IS DISTINCT FROM
</primary>
362 <primary>IS NOT DISTINCT FROM
</primary>
364 Ordinary comparison operators yield null (signifying
<quote>unknown<
/>),
365 not true or false, when either input is null. For example,
366 <literal>7 = NULL<
/> yields null. When this behavior is not suitable,
368 <literal>IS
<optional> NOT <
/> DISTINCT FROM
</literal> constructs:
370 <replaceable>expression
</replaceable> IS DISTINCT FROM
<replaceable>expression
</replaceable>
371 <replaceable>expression
</replaceable> IS NOT DISTINCT FROM
<replaceable>expression
</replaceable>
373 For non-null inputs,
<literal>IS DISTINCT FROM
</literal> is
374 the same as the
<literal><><
/> operator. However, if both
375 inputs are null it returns false, and if only one input is
376 null it returns true. Similarly,
<literal>IS NOT DISTINCT
377 FROM
</literal> is identical to
<literal>=
</literal> for non-null
378 inputs, but it returns true when both inputs are null, and false when only
379 one input is null. Thus, these constructs effectively act as though null
380 were a normal data value, rather than
<quote>unknown<
/>.
385 <primary>IS TRUE
</primary>
388 <primary>IS NOT TRUE
</primary>
391 <primary>IS FALSE
</primary>
394 <primary>IS NOT FALSE
</primary>
397 <primary>IS UNKNOWN
</primary>
400 <primary>IS NOT UNKNOWN
</primary>
402 Boolean values can also be tested using the constructs
404 <replaceable>expression
</replaceable> IS TRUE
405 <replaceable>expression
</replaceable> IS NOT TRUE
406 <replaceable>expression
</replaceable> IS FALSE
407 <replaceable>expression
</replaceable> IS NOT FALSE
408 <replaceable>expression
</replaceable> IS UNKNOWN
409 <replaceable>expression
</replaceable> IS NOT UNKNOWN
411 These will always return true or false, never a null value, even when the
413 A null input is treated as the logical value
<quote>unknown<
/>.
414 Notice that
<literal>IS UNKNOWN<
/> and
<literal>IS NOT UNKNOWN<
/> are
415 effectively the same as
<literal>IS NULL
</literal> and
416 <literal>IS NOT NULL
</literal>, respectively, except that the input
417 expression must be of Boolean type.
420 <!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
423 <primary>IS OF</primary>
426 <primary>IS NOT OF</primary>
428 It is possible to check the data type of an expression using the
431 <replaceable>expression</replaceable> IS OF (typename, ...)
432 <replaceable>expression</replaceable> IS NOT OF (typename, ...)
434 They return a boolean value based on whether the expression's data
435 type is one of the listed data types.
441 <sect1 id=
"functions-math">
442 <title>Mathematical Functions and Operators
</title>
445 Mathematical operators are provided for many
446 <productname>PostgreSQL
</productname> types. For types without
447 standard mathematical conventions
448 (e.g., date/time types) we
449 describe the actual behavior in subsequent sections.
453 <xref linkend=
"functions-math-op-table"> shows the available mathematical operators.
456 <table id=
"functions-math-op-table">
457 <title>Mathematical Operators
</title>
462 <entry>Operator
</entry>
463 <entry>Description
</entry>
464 <entry>Example
</entry>
465 <entry>Result
</entry>
471 <entry> <literal>+
</literal> </entry>
472 <entry>addition
</entry>
473 <entry><literal>2 +
3</literal></entry>
474 <entry><literal>5</literal></entry>
478 <entry> <literal>-
</literal> </entry>
479 <entry>subtraction
</entry>
480 <entry><literal>2 -
3</literal></entry>
481 <entry><literal>-
1</literal></entry>
485 <entry> <literal>*
</literal> </entry>
486 <entry>multiplication
</entry>
487 <entry><literal>2 *
3</literal></entry>
488 <entry><literal>6</literal></entry>
492 <entry> <literal>/
</literal> </entry>
493 <entry>division (integer division truncates the result)
</entry>
494 <entry><literal>4 /
2</literal></entry>
495 <entry><literal>2</literal></entry>
499 <entry> <literal>%
</literal> </entry>
500 <entry>modulo (remainder)
</entry>
501 <entry><literal>5 %
4</literal></entry>
502 <entry><literal>1</literal></entry>
506 <entry> <literal>^
</literal> </entry>
507 <entry>exponentiation
</entry>
508 <entry><literal>2.0 ^
3.0</literal></entry>
509 <entry><literal>8</literal></entry>
513 <entry> <literal>|/
</literal> </entry>
514 <entry>square root
</entry>
515 <entry><literal>|/
25.0</literal></entry>
516 <entry><literal>5</literal></entry>
520 <entry> <literal>||/
</literal> </entry>
521 <entry>cube root
</entry>
522 <entry><literal>||/
27.0</literal></entry>
523 <entry><literal>3</literal></entry>
527 <entry> <literal>!
</literal> </entry>
528 <entry>factorial
</entry>
529 <entry><literal>5 !
</literal></entry>
530 <entry><literal>120</literal></entry>
534 <entry> <literal>!!
</literal> </entry>
535 <entry>factorial (prefix operator)
</entry>
536 <entry><literal>!!
5</literal></entry>
537 <entry><literal>120</literal></entry>
541 <entry> <literal>@
</literal> </entry>
542 <entry>absolute value
</entry>
543 <entry><literal>@ -
5.0</literal></entry>
544 <entry><literal>5</literal></entry>
548 <entry> <literal>&</literal> </entry>
549 <entry>bitwise AND
</entry>
550 <entry><literal>91 & 15</literal></entry>
551 <entry><literal>11</literal></entry>
555 <entry> <literal>|
</literal> </entry>
556 <entry>bitwise OR
</entry>
557 <entry><literal>32 |
3</literal></entry>
558 <entry><literal>35</literal></entry>
562 <entry> <literal>#
</literal> </entry>
563 <entry>bitwise XOR
</entry>
564 <entry><literal>17 #
5</literal></entry>
565 <entry><literal>20</literal></entry>
569 <entry> <literal>~
</literal> </entry>
570 <entry>bitwise NOT
</entry>
571 <entry><literal>~
1</literal></entry>
572 <entry><literal>-
2</literal></entry>
576 <entry> <literal><<</literal> </entry>
577 <entry>bitwise shift left
</entry>
578 <entry><literal>1 << 4</literal></entry>
579 <entry><literal>16</literal></entry>
583 <entry> <literal>>></literal> </entry>
584 <entry>bitwise shift right
</entry>
585 <entry><literal>8 >> 2</literal></entry>
586 <entry><literal>2</literal></entry>
594 The bitwise operators work only on integral data types, whereas
595 the others are available for all numeric data types. The bitwise
596 operators are also available for the bit
597 string types
<type>bit
</type> and
<type>bit varying
</type>, as
598 shown in
<xref linkend=
"functions-bit-string-op-table">.
602 <xref linkend=
"functions-math-func-table"> shows the available
603 mathematical functions. In the table,
<literal>dp
</literal>
604 indicates
<type>double precision
</type>. Many of these functions
605 are provided in multiple forms with different argument types.
606 Except where noted, any given form of a function returns the same
607 data type as its argument.
608 The functions working with
<type>double precision
</type> data are mostly
609 implemented on top of the host system's C library; accuracy and behavior in
610 boundary cases can therefore vary depending on the host system.
614 <primary>abs
</primary>
617 <primary>cbrt
</primary>
620 <primary>ceiling
</primary>
623 <primary>degrees
</primary>
626 <primary>div
</primary>
629 <primary>exp
</primary>
632 <primary>floor
</primary>
635 <primary>ln
</primary>
638 <primary>log
</primary>
641 <primary>mod
</primary>
644 <primary>pi
</primary>
647 <primary>power
</primary>
650 <primary>radians
</primary>
653 <primary>random
</primary>
656 <primary>round
</primary>
659 <primary>setseed
</primary>
662 <primary>sign
</primary>
665 <primary>sqrt
</primary>
668 <primary>trunc
</primary>
671 <primary>width_bucket
</primary>
674 <table id=
"functions-math-func-table">
675 <title>Mathematical Functions
</title>
679 <entry>Function
</entry>
680 <entry>Return Type
</entry>
681 <entry>Description
</entry>
682 <entry>Example
</entry>
683 <entry>Result
</entry>
689 <entry><literal><function>abs<
/>(
<replaceable>x
</replaceable>)
</literal></entry>
690 <entry>(same as input)
</entry>
691 <entry>absolute value
</entry>
692 <entry><literal>abs(-
17.4)
</literal></entry>
693 <entry><literal>17.4</literal></entry>
697 <entry><literal><function>cbrt
</function>(
<type>dp
</type>)
</literal></entry>
698 <entry><type>dp
</type></entry>
699 <entry>cube root
</entry>
700 <entry><literal>cbrt(
27.0)
</literal></entry>
701 <entry><literal>3</literal></entry>
705 <entry><literal><function>ceil
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
706 <entry>(same as input)
</entry>
707 <entry>smallest integer not less than argument
</entry>
708 <entry><literal>ceil(-
42.8)
</literal></entry>
709 <entry><literal>-
42</literal></entry>
713 <entry><literal><function>ceiling
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
714 <entry>(same as input)
</entry>
715 <entry>smallest integer not less than argument (alias for
<function>ceil
</function>)
</entry>
716 <entry><literal>ceiling(-
95.3)
</literal></entry>
717 <entry><literal>-
95</literal></entry>
721 <entry><literal><function>degrees
</function>(
<type>dp
</type>)
</literal></entry>
722 <entry><type>dp
</type></entry>
723 <entry>radians to degrees
</entry>
724 <entry><literal>degrees(
0.5)
</literal></entry>
725 <entry><literal>28.6478897565412</literal></entry>
729 <entry><literal><function>div
</function>(
<parameter>y
</parameter> <type>numeric<
/>,
730 <parameter>x
</parameter> <type>numeric<
/>)
</literal></entry>
731 <entry><type>numeric<
/></entry>
732 <entry>integer quotient of
<parameter>y
</parameter>/
<parameter>x
</parameter></entry>
733 <entry><literal>div(
9,
4)
</literal></entry>
734 <entry><literal>2</literal></entry>
738 <entry><literal><function>exp
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
739 <entry>(same as input)
</entry>
740 <entry>exponential
</entry>
741 <entry><literal>exp(
1.0)
</literal></entry>
742 <entry><literal>2.71828182845905</literal></entry>
746 <entry><literal><function>floor
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
747 <entry>(same as input)
</entry>
748 <entry>largest integer not greater than argument
</entry>
749 <entry><literal>floor(-
42.8)
</literal></entry>
750 <entry><literal>-
43</literal></entry>
754 <entry><literal><function>ln
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
755 <entry>(same as input)
</entry>
756 <entry>natural logarithm
</entry>
757 <entry><literal>ln(
2.0)
</literal></entry>
758 <entry><literal>0.693147180559945</literal></entry>
762 <entry><literal><function>log
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
763 <entry>(same as input)
</entry>
764 <entry>base
10 logarithm
</entry>
765 <entry><literal>log(
100.0)
</literal></entry>
766 <entry><literal>2</literal></entry>
770 <entry><literal><function>log
</function>(
<parameter>b
</parameter> <type>numeric
</type>,
771 <parameter>x
</parameter> <type>numeric
</type>)
</literal></entry>
772 <entry><type>numeric
</type></entry>
773 <entry>logarithm to base
<parameter>b
</parameter></entry>
774 <entry><literal>log(
2.0,
64.0)
</literal></entry>
775 <entry><literal>6.0000000000</literal></entry>
779 <entry><literal><function>mod
</function>(
<parameter>y
</parameter>,
780 <parameter>x
</parameter>)
</literal></entry>
781 <entry>(same as argument types)
</entry>
782 <entry>remainder of
<parameter>y
</parameter>/
<parameter>x
</parameter></entry>
783 <entry><literal>mod(
9,
4)
</literal></entry>
784 <entry><literal>1</literal></entry>
788 <entry><literal><function>pi
</function>()
</literal></entry>
789 <entry><type>dp
</type></entry>
790 <entry><quote>π</quote> constant
</entry>
791 <entry><literal>pi()
</literal></entry>
792 <entry><literal>3.14159265358979</literal></entry>
796 <entry><literal><function>power
</function>(
<parameter>a
</parameter> <type>dp
</type>,
797 <parameter>b
</parameter> <type>dp
</type>)
</literal></entry>
798 <entry><type>dp
</type></entry>
799 <entry><parameter>a<
/> raised to the power of
<parameter>b
</parameter></entry>
800 <entry><literal>power(
9.0,
3.0)
</literal></entry>
801 <entry><literal>729</literal></entry>
805 <entry><literal><function>power
</function>(
<parameter>a
</parameter> <type>numeric
</type>,
806 <parameter>b
</parameter> <type>numeric
</type>)
</literal></entry>
807 <entry><type>numeric
</type></entry>
808 <entry><parameter>a<
/> raised to the power of
<parameter>b
</parameter></entry>
809 <entry><literal>power(
9.0,
3.0)
</literal></entry>
810 <entry><literal>729</literal></entry>
814 <entry><literal><function>radians
</function>(
<type>dp
</type>)
</literal></entry>
815 <entry><type>dp
</type></entry>
816 <entry>degrees to radians
</entry>
817 <entry><literal>radians(
45.0)
</literal></entry>
818 <entry><literal>0.785398163397448</literal></entry>
822 <entry><literal><function>random
</function>()
</literal></entry>
823 <entry><type>dp
</type></entry>
824 <entry>random value between
0.0 and
1.0, inclusive
</entry>
825 <entry><literal>random()
</literal></entry>
830 <entry><literal><function>round
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
831 <entry>(same as input)
</entry>
832 <entry>round to nearest integer
</entry>
833 <entry><literal>round(
42.4)
</literal></entry>
834 <entry><literal>42</literal></entry>
838 <entry><literal><function>round
</function>(
<parameter>v
</parameter> <type>numeric
</type>,
<parameter>s
</parameter> <type>int
</type>)
</literal></entry>
839 <entry><type>numeric
</type></entry>
840 <entry>round to
<parameter>s
</parameter> decimal places
</entry>
841 <entry><literal>round(
42.4382,
2)
</literal></entry>
842 <entry><literal>42.44</literal></entry>
846 <entry><literal><function>setseed
</function>(
<type>dp
</type>)
</literal></entry>
847 <entry><type>void
</type></entry>
848 <entry>set seed for subsequent
<literal>random()
</literal> calls (value between -
1.0 and
849 1.0, inclusive)
</entry>
850 <entry><literal>setseed(
0.54823)
</literal></entry>
855 <entry><literal><function>sign
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
856 <entry>(same as input)
</entry>
857 <entry>sign of the argument (-
1,
0, +
1)
</entry>
858 <entry><literal>sign(-
8.4)
</literal></entry>
859 <entry><literal>-
1</literal></entry>
863 <entry><literal><function>sqrt
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
864 <entry>(same as input)
</entry>
865 <entry>square root
</entry>
866 <entry><literal>sqrt(
2.0)
</literal></entry>
867 <entry><literal>1.4142135623731</literal></entry>
871 <entry><literal><function>trunc
</function>(
<type>dp
</type> or
<type>numeric
</type>)
</literal></entry>
872 <entry>(same as input)
</entry>
873 <entry>truncate toward zero
</entry>
874 <entry><literal>trunc(
42.8)
</literal></entry>
875 <entry><literal>42</literal></entry>
879 <entry><literal><function>trunc
</function>(
<parameter>v
</parameter> <type>numeric
</type>,
<parameter>s
</parameter> <type>int
</type>)
</literal></entry>
880 <entry><type>numeric
</type></entry>
881 <entry>truncate to
<parameter>s
</parameter> decimal places
</entry>
882 <entry><literal>trunc(
42.4382,
2)
</literal></entry>
883 <entry><literal>42.43</literal></entry>
887 <entry><literal><function>width_bucket
</function>(
<parameter>op
</parameter> <type>numeric
</type>,
<parameter>b1
</parameter> <type>numeric
</type>,
<parameter>b2
</parameter> <type>numeric
</type>,
<parameter>count
</parameter> <type>int
</type>)
</literal></entry>
888 <entry><type>int
</type></entry>
889 <entry>return the bucket to which
<parameter>operand<
/> would
890 be assigned in an equidepth histogram with
<parameter>count<
/>
891 buckets, in the range
<parameter>b1<
/> to
<parameter>b2<
/></entry>
892 <entry><literal>width_bucket(
5.35,
0.024,
10.06,
5)
</literal></entry>
893 <entry><literal>3</literal></entry>
897 <entry><literal><function>width_bucket
</function>(
<parameter>op
</parameter> <type>dp
</type>,
<parameter>b1
</parameter> <type>dp
</type>,
<parameter>b2
</parameter> <type>dp
</type>,
<parameter>count
</parameter> <type>int
</type>)
</literal></entry>
898 <entry><type>int
</type></entry>
899 <entry>return the bucket to which
<parameter>operand<
/> would
900 be assigned in an equidepth histogram with
<parameter>count<
/>
901 buckets, in the range
<parameter>b1<
/> to
<parameter>b2<
/></entry>
902 <entry><literal>width_bucket(
5.35,
0.024,
10.06,
5)
</literal></entry>
903 <entry><literal>3</literal></entry>
910 Finally,
<xref linkend=
"functions-math-trig-table"> shows the
911 available trigonometric functions. All trigonometric functions
912 take arguments and return values of type
<type>double
917 <primary>acos
</primary>
920 <primary>asin
</primary>
923 <primary>atan
</primary>
926 <primary>atan2
</primary>
929 <primary>cos
</primary>
932 <primary>cot
</primary>
935 <primary>sin
</primary>
938 <primary>tan
</primary>
941 <table id=
"functions-math-trig-table">
942 <title>Trigonometric Functions
</title>
947 <entry>Function
</entry>
948 <entry>Description
</entry>
954 <entry><literal><function>acos
</function>(
<replaceable>x
</replaceable>)
</literal></entry>
955 <entry>inverse cosine
</entry>
959 <entry><literal><function>asin
</function>(
<replaceable>x
</replaceable>)
</literal></entry>
960 <entry>inverse sine
</entry>
964 <entry><literal><function>atan
</function>(
<replaceable>x
</replaceable>)
</literal></entry>
965 <entry>inverse tangent
</entry>
969 <entry><literal><function>atan2
</function>(
<replaceable>y
</replaceable>,
970 <replaceable>x
</replaceable>)
</literal></entry>
971 <entry>inverse tangent of
972 <literal><replaceable>y
</replaceable>/
<replaceable>x
</replaceable></literal></entry>
976 <entry><literal><function>cos
</function>(
<replaceable>x
</replaceable>)
</literal></entry>
977 <entry>cosine
</entry>
981 <entry><literal><function>cot
</function>(
<replaceable>x
</replaceable>)
</literal></entry>
982 <entry>cotangent
</entry>
986 <entry><literal><function>sin
</function>(
<replaceable>x
</replaceable>)
</literal></entry>
991 <entry><literal><function>tan
</function>(
<replaceable>x
</replaceable>)
</literal></entry>
992 <entry>tangent
</entry>
1001 <sect1 id=
"functions-string">
1002 <title>String Functions and Operators
</title>
1005 This section describes functions and operators for examining and
1006 manipulating string values. Strings in this context include values
1007 of the types
<type>character
</type>,
<type>character varying
</type>,
1008 and
<type>text
</type>. Unless otherwise noted, all
1009 of the functions listed below work on all of these types, but be
1010 wary of potential effects of automatic space-padding when using the
1011 <type>character
</type> type. Some functions also exist
1012 natively for the bit-string types.
1016 <acronym>SQL
</acronym> defines some string functions that use
1017 key words, rather than commas, to separate
1018 arguments. Details are in
1019 <xref linkend=
"functions-string-sql">.
1020 <productname>PostgreSQL<
/> also provides versions of these functions
1021 that use the regular function invocation syntax
1022 (see
<xref linkend=
"functions-string-other">).
1027 Before
<productname>PostgreSQL
</productname> 8.3, these functions would
1028 silently accept values of several non-string data types as well, due to
1029 the presence of implicit coercions from those data types to
1030 <type>text<
/>. Those coercions have been removed because they frequently
1031 caused surprising behaviors. However, the string concatenation operator
1032 (
<literal>||<
/>) still accepts non-string input, so long as at least one
1033 input is of a string type, as shown in
<xref
1034 linkend=
"functions-string-sql">. For other cases, insert an explicit
1035 coercion to
<type>text<
/> if you need to duplicate the previous behavior.
1040 <primary>bit_length
</primary>
1043 <primary>char_length
</primary>
1046 <primary>lower
</primary>
1049 <primary>octet_length
</primary>
1052 <primary>overlay
</primary>
1055 <primary>position
</primary>
1058 <primary>substring
</primary>
1061 <primary>trim
</primary>
1064 <primary>upper
</primary>
1067 <table id=
"functions-string-sql">
1068 <title><acronym>SQL
</acronym> String Functions and Operators
</title>
1072 <entry>Function
</entry>
1073 <entry>Return Type
</entry>
1074 <entry>Description
</entry>
1075 <entry>Example
</entry>
1076 <entry>Result
</entry>
1082 <entry><literal><parameter>string
</parameter> <literal>||
</literal>
1083 <parameter>string
</parameter></literal></entry>
1084 <entry> <type>text
</type> </entry>
1086 String concatenation
1088 <primary>character string
</primary>
1089 <secondary>concatenation
</secondary>
1092 <entry><literal>'Post' || 'greSQL'
</literal></entry>
1093 <entry><literal>PostgreSQL
</literal></entry>
1098 <literal><parameter>string
</parameter> <literal>||
</literal>
1099 <parameter>non-string
</parameter></literal>
1101 <literal><parameter>non-string
</parameter> <literal>||
</literal>
1102 <parameter>string
</parameter></literal>
1104 <entry> <type>text
</type> </entry>
1106 String concatenation with one non-string input
1108 <entry><literal>'Value: ' ||
42</literal></entry>
1109 <entry><literal>Value:
42</literal></entry>
1113 <entry><literal><function>bit_length
</function>(
<parameter>string
</parameter>)
</literal></entry>
1114 <entry><type>int
</type></entry>
1115 <entry>Number of bits in string
</entry>
1116 <entry><literal>bit_length('jose')
</literal></entry>
1117 <entry><literal>32</literal></entry>
1121 <entry><literal><function>char_length
</function>(
<parameter>string
</parameter>)
</literal> or
<literal><function>character_length
</function>(
<parameter>string
</parameter>)
</literal></entry>
1122 <entry><type>int
</type></entry>
1124 Number of characters in string
1126 <primary>character string
</primary>
1127 <secondary>length
</secondary>
1130 <primary>length
</primary>
1131 <secondary sortas=
"character string">of a character string
</secondary>
1132 <see>character string, length
</see>
1135 <entry><literal>char_length('jose')
</literal></entry>
1136 <entry><literal>4</literal></entry>
1140 <entry><literal><function>lower
</function>(
<parameter>string
</parameter>)
</literal></entry>
1141 <entry><type>text
</type></entry>
1142 <entry>Convert string to lower case
</entry>
1143 <entry><literal>lower('TOM')
</literal></entry>
1144 <entry><literal>tom
</literal></entry>
1148 <entry><literal><function>octet_length
</function>(
<parameter>string
</parameter>)
</literal></entry>
1149 <entry><type>int
</type></entry>
1150 <entry>Number of bytes in string
</entry>
1151 <entry><literal>octet_length('jose')
</literal></entry>
1152 <entry><literal>4</literal></entry>
1156 <entry><literal><function>overlay
</function>(
<parameter>string
</parameter> placing
<parameter>string
</parameter> from
<type>int
</type> <optional>for
<type>int
</type></optional>)
</literal></entry>
1157 <entry><type>text
</type></entry>
1161 <entry><literal>overlay('Txxxxas' placing 'hom' from
2 for
4)
</literal></entry>
1162 <entry><literal>Thomas
</literal></entry>
1166 <entry><literal><function>position
</function>(
<parameter>substring
</parameter> in
<parameter>string
</parameter>)
</literal></entry>
1167 <entry><type>int
</type></entry>
1168 <entry>Location of specified substring
</entry>
1169 <entry><literal>position('om' in 'Thomas')
</literal></entry>
1170 <entry><literal>3</literal></entry>
1174 <entry><literal><function>substring
</function>(
<parameter>string
</parameter> <optional>from
<type>int
</type></optional> <optional>for
<type>int
</type></optional>)
</literal></entry>
1175 <entry><type>text
</type></entry>
1179 <entry><literal>substring('Thomas' from
2 for
3)
</literal></entry>
1180 <entry><literal>hom
</literal></entry>
1184 <entry><literal><function>substring
</function>(
<parameter>string
</parameter> from
<replaceable>pattern
</replaceable>)
</literal></entry>
1185 <entry><type>text
</type></entry>
1187 Extract substring matching POSIX regular expression. See
1188 <xref linkend=
"functions-matching"> for more information on pattern
1191 <entry><literal>substring('Thomas' from '...$')
</literal></entry>
1192 <entry><literal>mas
</literal></entry>
1196 <entry><literal><function>substring
</function>(
<parameter>string
</parameter> from
<replaceable>pattern
</replaceable> for
<replaceable>escape
</replaceable>)
</literal></entry>
1197 <entry><type>text
</type></entry>
1199 Extract substring matching
<acronym>SQL
</acronym> regular expression.
1200 See
<xref linkend=
"functions-matching"> for more information on
1203 <entry><literal>substring('Thomas' from '%#
"o_a#"_' for '#')
</literal></entry>
1204 <entry><literal>oma
</literal></entry>
1209 <literal><function>trim
</function>(
<optional>leading | trailing | both
</optional>
1210 <optional><parameter>characters
</parameter></optional> from
1211 <parameter>string
</parameter>)
</literal>
1213 <entry><type>text
</type></entry>
1215 Remove the longest string containing only the
1216 <parameter>characters
</parameter> (a space by default) from the
1217 start/end/both ends of the
<parameter>string
</parameter>
1219 <entry><literal>trim(both 'x' from 'xTomxx')
</literal></entry>
1220 <entry><literal>Tom
</literal></entry>
1224 <entry><literal><function>upper
</function>(
<parameter>string
</parameter>)
</literal></entry>
1225 <entry><type>text
</type></entry>
1226 <entry>Convert string to uppercase
</entry>
1227 <entry><literal>upper('tom')
</literal></entry>
1228 <entry><literal>TOM
</literal></entry>
1235 Additional string manipulation functions are available and are
1236 listed in
<xref linkend=
"functions-string-other">. Some of them are used internally to implement the
1237 <acronym>SQL
</acronym>-standard string functions listed in
<xref linkend=
"functions-string-sql">.
1241 <primary>ascii
</primary>
1244 <primary>btrim
</primary>
1247 <primary>chr
</primary>
1250 <primary>convert
</primary>
1253 <primary>convert_from
</primary>
1256 <primary>convert_to
</primary>
1259 <primary>decode
</primary>
1262 <primary>encode
</primary>
1265 <primary>initcap
</primary>
1268 <primary>lpad
</primary>
1271 <primary>ltrim
</primary>
1274 <primary>md5
</primary>
1277 <primary>pg_client_encoding
</primary>
1280 <primary>quote_ident
</primary>
1283 <primary>quote_literal
</primary>
1286 <primary>quote_nullable
</primary>
1289 <primary>repeat
</primary>
1292 <primary>replace
</primary>
1295 <primary>rpad
</primary>
1298 <primary>rtrim
</primary>
1301 <primary>split_part
</primary>
1304 <primary>strpos
</primary>
1307 <primary>substr
</primary>
1310 <primary>to_ascii
</primary>
1313 <primary>to_hex
</primary>
1316 <primary>translate
</primary>
1319 <table id=
"functions-string-other">
1320 <title>Other String Functions
</title>
1324 <entry>Function
</entry>
1325 <entry>Return Type
</entry>
1326 <entry>Description
</entry>
1327 <entry>Example
</entry>
1328 <entry>Result
</entry>
1334 <entry><literal><function>ascii
</function>(
<parameter>string
</parameter>)
</literal></entry>
1335 <entry><type>int
</type></entry>
1337 <acronym>ASCII
</acronym> code of the first character of the
1338 argument. For
<acronym>UTF8
</acronym> returns the Unicode code
1339 point of the character. For other multibyte encodings, the
1340 argument must be an
<acronym>ASCII
</acronym> character.
1342 <entry><literal>ascii('x')
</literal></entry>
1343 <entry><literal>120</literal></entry>
1347 <entry><literal><function>btrim
</function>(
<parameter>string
</parameter> <type>text
</type>
1348 <optional>,
<parameter>characters
</parameter> <type>text
</type></optional>)
</literal></entry>
1349 <entry><type>text
</type></entry>
1351 Remove the longest string consisting only of characters
1352 in
<parameter>characters
</parameter> (a space by default)
1353 from the start and end of
<parameter>string
</parameter>
1355 <entry><literal>btrim('xyxtrimyyx', 'xy')
</literal></entry>
1356 <entry><literal>trim
</literal></entry>
1360 <entry><literal><function>chr
</function>(
<type>int
</type>)
</literal></entry>
1361 <entry><type>text
</type></entry>
1363 Character with the given code. For
<acronym>UTF8
</acronym> the
1364 argument is treated as a Unicode code point. For other multibyte
1365 encodings the argument must designate an
1366 <acronym>ASCII
</acronym> character. The NULL (
0) character is not
1367 allowed because text data types cannot store such bytes.
1369 <entry><literal>chr(
65)
</literal></entry>
1370 <entry><literal>A
</literal></entry>
1375 <literal><function>convert
</function>(
<parameter>string
</parameter> <type>bytea
</type>,
1376 <parameter>src_encoding
</parameter> <type>name
</type>,
1377 <parameter>dest_encoding
</parameter> <type>name
</type>)
</literal>
1379 <entry><type>bytea
</type></entry>
1381 Convert string to
<parameter>dest_encoding
</parameter>. The
1382 original encoding is specified by
1383 <parameter>src_encoding
</parameter>. The
1384 <parameter>string
</parameter> must be valid in this encoding.
1385 Conversions can be defined by
<command>CREATE CONVERSION
</command>.
1386 Also there are some predefined conversions. See
<xref
1387 linkend=
"conversion-names"> for available conversions.
1389 <entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')
</literal></entry>
1390 <entry><literal>text_in_utf8
</literal> represented in Latin-
1
1391 encoding (ISO
8859-
1)
</entry>
1396 <literal><function>convert_from
</function>(
<parameter>string
</parameter> <type>bytea
</type>,
1397 <parameter>src_encoding
</parameter> <type>name
</type>)
</literal>
1399 <entry><type>text
</type></entry>
1401 Convert string to the database encoding. The original encoding
1402 is specified by
<parameter>src_encoding
</parameter>. The
1403 <parameter>string
</parameter> must be valid in this encoding.
1405 <entry><literal>convert_from('text_in_utf8', 'UTF8')
</literal></entry>
1406 <entry><literal>text_in_utf8
</literal> represented in the current database encoding
</entry>
1411 <literal><function>convert_to
</function>(
<parameter>string
</parameter> <type>text
</type>,
1412 <parameter>dest_encoding
</parameter> <type>name
</type>)
</literal>
1414 <entry><type>bytea
</type></entry>
1416 Convert string to
<parameter>dest_encoding
</parameter>.
1418 <entry><literal>convert_to('some text', 'UTF8')
</literal></entry>
1419 <entry><literal>some text
</literal> represented in the UTF8 encoding
</entry>
1424 <literal><function>decode
</function>(
<parameter>string
</parameter> <type>text
</type>,
1425 <parameter>type
</parameter> <type>text
</type>)
</literal>
1427 <entry><type>bytea
</type></entry>
1429 Decode binary data from
<parameter>string
</parameter> previously
1430 encoded with
<function>encode<
/>. Parameter type is same as in
<function>encode<
/>.
1432 <entry><literal>decode('MTIzAAE=', 'base64')
</literal></entry>
1433 <entry><literal>123\
000\
001</literal></entry>
1438 <literal><function>encode
</function>(
<parameter>data
</parameter> <type>bytea
</type>,
1439 <parameter>type
</parameter> <type>text
</type>)
</literal>
1441 <entry><type>text
</type></entry>
1443 Encode binary data to different representation. Supported
1444 types are:
<literal>base64<
/>,
<literal>hex<
/>,
<literal>escape<
/>.
1445 <literal>Escape<
/> merely outputs null bytes as
<literal>\
000<
/> and
1446 doubles backslashes.
1448 <entry><literal>encode(E'
123\\
000\\
001', 'base64')
</literal></entry>
1449 <entry><literal>MTIzAAE=
</literal></entry>
1453 <entry><literal><function>initcap
</function>(
<parameter>string
</parameter>)
</literal></entry>
1454 <entry><type>text
</type></entry>
1456 Convert the first letter of each word to uppercase and the
1457 rest to lowercase. Words are sequences of alphanumeric
1458 characters separated by non-alphanumeric characters.
1460 <entry><literal>initcap('hi THOMAS')
</literal></entry>
1461 <entry><literal>Hi Thomas
</literal></entry>
1465 <entry><literal><function>length
</function>(
<parameter>string
</parameter>)
</literal></entry>
1466 <entry><type>int
</type></entry>
1468 Number of characters in
<parameter>string
</parameter>
1470 <entry><literal>length('jose')
</literal></entry>
1471 <entry><literal>4</literal></entry>
1475 <entry><literal><function>length
</function>(
<parameter>string
</parameter><type>bytea
</type>,
1476 <parameter>encoding
</parameter> <type>name
</type> )
</literal></entry>
1477 <entry><type>int
</type></entry>
1479 Number of characters in
<parameter>string
</parameter> in the given
1480 <parameter>encoding
</parameter>. The
<parameter>string
</parameter>
1481 must be valid in this encoding.
1483 <entry><literal>length('jose', 'UTF8')
</literal></entry>
1484 <entry><literal>4</literal></entry>
1489 <literal><function>lpad
</function>(
<parameter>string
</parameter> <type>text
</type>,
1490 <parameter>length
</parameter> <type>int
</type>
1491 <optional>,
<parameter>fill
</parameter> <type>text
</type></optional>)
</literal>
1493 <entry><type>text
</type></entry>
1495 Fill up the
<parameter>string
</parameter> to length
1496 <parameter>length
</parameter> by prepending the characters
1497 <parameter>fill
</parameter> (a space by default). If the
1498 <parameter>string
</parameter> is already longer than
1499 <parameter>length
</parameter> then it is truncated (on the
1502 <entry><literal>lpad('hi',
5, 'xy')
</literal></entry>
1503 <entry><literal>xyxhi
</literal></entry>
1507 <entry><literal><function>ltrim
</function>(
<parameter>string
</parameter> <type>text
</type>
1508 <optional>,
<parameter>characters
</parameter> <type>text
</type></optional>)
</literal>
1510 <entry><type>text
</type></entry>
1512 Remove the longest string containing only characters from
1513 <parameter>characters
</parameter> (a space by default) from the start of
1514 <parameter>string
</parameter>
1516 <entry><literal>ltrim('zzzytrim', 'xyz')
</literal></entry>
1517 <entry><literal>trim
</literal></entry>
1521 <entry><literal><function>md5
</function>(
<parameter>string
</parameter>)
</literal></entry>
1522 <entry><type>text
</type></entry>
1524 Calculates the MD5 hash of
<parameter>string
</parameter>,
1525 returning the result in hexadecimal
1527 <entry><literal>md5('abc')
</literal></entry>
1528 <entry><literal>900150983cd24fb0 d6963f7d28e17f72
</literal></entry>
1532 <entry><literal><function>pg_client_encoding
</function>()
</literal></entry>
1533 <entry><type>name
</type></entry>
1535 Current client encoding name
1537 <entry><literal>pg_client_encoding()
</literal></entry>
1538 <entry><literal>SQL_ASCII
</literal></entry>
1542 <entry><literal><function>quote_ident
</function>(
<parameter>string
</parameter> <type>text
</type>)
</literal></entry>
1543 <entry><type>text
</type></entry>
1545 Return the given string suitably quoted to be used as an identifier
1546 in an
<acronym>SQL
</acronym> statement string.
1547 Quotes are added only if necessary (i.e., if the string contains
1548 non-identifier characters or would be case-folded).
1549 Embedded quotes are properly doubled.
1550 See also
<xref linkend=
"plpgsql-quote-literal-example">.
1552 <entry><literal>quote_ident('Foo bar')
</literal></entry>
1553 <entry><literal>"Foo bar"</literal></entry>
1557 <entry><literal><function>quote_literal
</function>(
<parameter>string
</parameter> <type>text
</type>)
</literal></entry>
1558 <entry><type>text
</type></entry>
1560 Return the given string suitably quoted to be used as a string literal
1561 in an
<acronym>SQL
</acronym> statement string.
1562 Embedded single-quotes and backslashes are properly doubled.
1563 Note that
<function>quote_literal
</function> returns null on null
1564 input; if the argument might be null,
1565 <function>quote_nullable
</function> is often more suitable.
1566 See also
<xref linkend=
"plpgsql-quote-literal-example">.
1568 <entry><literal>quote_literal('O\'Reilly')
</literal></entry>
1569 <entry><literal>'O''Reilly'
</literal></entry>
1573 <entry><literal><function>quote_literal
</function>(
<parameter>value
</parameter> <type>anyelement
</type>)
</literal></entry>
1574 <entry><type>text
</type></entry>
1576 Coerce the given value to text and then quote it as a literal.
1577 Embedded single-quotes and backslashes are properly doubled.
1579 <entry><literal>quote_literal(
42.5)
</literal></entry>
1580 <entry><literal>'
42.5'
</literal></entry>
1584 <entry><literal><function>quote_nullable
</function>(
<parameter>string
</parameter> <type>text
</type>)
</literal></entry>
1585 <entry><type>text
</type></entry>
1587 Return the given string suitably quoted to be used as a string literal
1588 in an
<acronym>SQL
</acronym> statement string; or, if the argument
1589 is null, return
<literal>NULL<
/>.
1590 Embedded single-quotes and backslashes are properly doubled.
1591 See also
<xref linkend=
"plpgsql-quote-literal-example">.
1593 <entry><literal>quote_nullable(NULL)
</literal></entry>
1594 <entry><literal>NULL
</literal></entry>
1598 <entry><literal><function>quote_nullable
</function>(
<parameter>value
</parameter> <type>anyelement
</type>)
</literal></entry>
1599 <entry><type>text
</type></entry>
1601 Coerce the given value to text and then quote it as a literal;
1602 or, if the argument is null, return
<literal>NULL<
/>.
1603 Embedded single-quotes and backslashes are properly doubled.
1605 <entry><literal>quote_nullable(
42.5)
</literal></entry>
1606 <entry><literal>'
42.5'
</literal></entry>
1610 <entry><literal><function>regexp_matches
</function>(
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type>])
</literal></entry>
1611 <entry><type>setof text[]
</type></entry>
1613 Return all captured substrings resulting from matching a POSIX regular
1614 expression against the
<parameter>string
</parameter>. See
1615 <xref linkend=
"functions-posix-regexp"> for more information.
1617 <entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')
</literal></entry>
1618 <entry><literal>{bar,beque}
</literal></entry>
1622 <entry><literal><function>regexp_replace
</function>(
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type>,
<parameter>replacement
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type>])
</literal></entry>
1623 <entry><type>text
</type></entry>
1625 Replace substring(s) matching a POSIX regular expression. See
1626 <xref linkend=
"functions-posix-regexp"> for more information.
1628 <entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')
</literal></entry>
1629 <entry><literal>ThM
</literal></entry>
1633 <entry><literal><function>regexp_split_to_array
</function>(
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type> ])
</literal></entry>
1634 <entry><type>text[]
</type></entry>
1636 Split
<parameter>string
</parameter> using a POSIX regular expression as
1637 the delimiter. See
<xref linkend=
"functions-posix-regexp"> for more
1640 <entry><literal>regexp_split_to_array('hello world', E'\\s+')
</literal></entry>
1641 <entry><literal>{hello,world}
</literal></entry>
1645 <entry><literal><function>regexp_split_to_table
</function>(
<parameter>string
</parameter> <type>text
</type>,
<parameter>pattern
</parameter> <type>text
</type> [,
<parameter>flags
</parameter> <type>text
</type>])
</literal></entry>
1646 <entry><type>setof text
</type></entry>
1648 Split
<parameter>string
</parameter> using a POSIX regular expression as
1649 the delimiter. See
<xref linkend=
"functions-posix-regexp"> for more
1652 <entry><literal>regexp_split_to_table('hello world', E'\\s+')
</literal></entry>
1653 <entry><literal>hello
</literal><para><literal>world
</literal></para> (
2 rows)
</entry>
1657 <entry><literal><function>repeat
</function>(
<parameter>string
</parameter> <type>text
</type>,
<parameter>number
</parameter> <type>int
</type>)
</literal></entry>
1658 <entry><type>text
</type></entry>
1659 <entry>Repeat
<parameter>string
</parameter> the specified
1660 <parameter>number
</parameter> of times
</entry>
1661 <entry><literal>repeat('Pg',
4)
</literal></entry>
1662 <entry><literal>PgPgPgPg
</literal></entry>
1666 <entry><literal><function>replace
</function>(
<parameter>string
</parameter> <type>text
</type>,
1667 <parameter>from
</parameter> <type>text
</type>,
1668 <parameter>to
</parameter> <type>text
</type>)
</literal></entry>
1669 <entry><type>text
</type></entry>
1670 <entry>Replace all occurrences in
<parameter>string
</parameter> of substring
1671 <parameter>from
</parameter> with substring
<parameter>to
</parameter>
1673 <entry><literal>replace('abcdefabcdef', 'cd', 'XX')
</literal></entry>
1674 <entry><literal>abXXefabXXef
</literal></entry>
1679 <literal><function>rpad
</function>(
<parameter>string
</parameter> <type>text
</type>,
1680 <parameter>length
</parameter> <type>int
</type>
1681 <optional>,
<parameter>fill
</parameter> <type>text
</type></optional>)
</literal>
1683 <entry><type>text
</type></entry>
1685 Fill up the
<parameter>string
</parameter> to length
1686 <parameter>length
</parameter> by appending the characters
1687 <parameter>fill
</parameter> (a space by default). If the
1688 <parameter>string
</parameter> is already longer than
1689 <parameter>length
</parameter> then it is truncated.
1691 <entry><literal>rpad('hi',
5, 'xy')
</literal></entry>
1692 <entry><literal>hixyx
</literal></entry>
1696 <entry><literal><function>rtrim
</function>(
<parameter>string
</parameter> <type>text
</type>
1697 <optional>,
<parameter>characters
</parameter> <type>text
</type></optional>)
</literal>
1699 <entry><type>text
</type></entry>
1701 Remove the longest string containing only characters from
1702 <parameter>characters
</parameter> (a space by default) from the end of
1703 <parameter>string
</parameter>
1705 <entry><literal>rtrim('trimxxxx', 'x')
</literal></entry>
1706 <entry><literal>trim
</literal></entry>
1710 <entry><literal><function>split_part
</function>(
<parameter>string
</parameter> <type>text
</type>,
1711 <parameter>delimiter
</parameter> <type>text
</type>,
1712 <parameter>field
</parameter> <type>int
</type>)
</literal></entry>
1713 <entry><type>text
</type></entry>
1714 <entry>Split
<parameter>string
</parameter> on
<parameter>delimiter
</parameter>
1715 and return the given field (counting from one)
1717 <entry><literal>split_part('abc~@~def~@~ghi', '~@~',
2)
</literal></entry>
1718 <entry><literal>def
</literal></entry>
1722 <entry><literal><function>strpos
</function>(
<parameter>string
</parameter>,
<parameter>substring
</parameter>)
</literal></entry>
1723 <entry><type>int
</type></entry>
1725 Location of specified substring (same as
1726 <literal>position(
<parameter>substring
</parameter> in
1727 <parameter>string
</parameter>)
</literal>, but note the reversed
1730 <entry><literal>strpos('high', 'ig')
</literal></entry>
1731 <entry><literal>2</literal></entry>
1735 <entry><literal><function>substr
</function>(
<parameter>string
</parameter>,
<parameter>from
</parameter> <optional>,
<parameter>count
</parameter></optional>)
</literal></entry>
1736 <entry><type>text
</type></entry>
1738 Extract substring (same as
1739 <literal>substring(
<parameter>string
</parameter> from
<parameter>from
</parameter> for
<parameter>count
</parameter>)
</literal>)
1741 <entry><literal>substr('alphabet',
3,
2)
</literal></entry>
1742 <entry><literal>ph
</literal></entry>
1746 <entry><literal><function>to_ascii
</function>(
<parameter>string
</parameter> <type>text
</type>
1747 <optional>,
<parameter>encoding
</parameter> <type>text
</type></optional>)
</literal></entry>
1748 <entry><type>text
</type></entry>
1751 Convert
<parameter>string
</parameter> to
<acronym>ASCII
</acronym> from another encoding
1752 (only supports conversion from
<literal>LATIN1<
/>,
<literal>LATIN2<
/>,
<literal>LATIN9<
/>,
1753 and
<literal>WIN1250<
/> encodings)
1756 <entry><literal>to_ascii('Karel')
</literal></entry>
1757 <entry><literal>Karel
</literal></entry>
1761 <entry><literal><function>to_hex
</function>(
<parameter>number
</parameter> <type>int
</type>
1762 or
<type>bigint
</type>)
</literal></entry>
1763 <entry><type>text
</type></entry>
1764 <entry>Convert
<parameter>number
</parameter> to its equivalent hexadecimal
1767 <entry><literal>to_hex(
2147483647)
</literal></entry>
1768 <entry><literal>7fffffff
</literal></entry>
1773 <literal><function>translate
</function>(
<parameter>string
</parameter> <type>text
</type>,
1774 <parameter>from
</parameter> <type>text
</type>,
1775 <parameter>to
</parameter> <type>text
</type>)
</literal>
1777 <entry><type>text
</type></entry>
1779 Any character in
<parameter>string
</parameter> that matches a
1780 character in the
<parameter>from
</parameter> set is replaced by
1781 the corresponding character in the
<parameter>to
</parameter>
1784 <entry><literal>translate('
12345', '
14', 'ax')
</literal></entry>
1785 <entry><literal>a23x5
</literal></entry>
1793 <table id=
"conversion-names">
1794 <title>Built-in Conversions
</title>
1798 <entry>Conversion Name
1801 The conversion names follow a standard naming scheme: The
1802 official name of the source encoding with all
1803 non-alphanumeric characters replaced by underscores, followed
1804 by
<literal>_to_
</literal>, followed by the similarly processed
1805 destination encoding name. Therefore, the names might deviate
1806 from the customary encoding names.
1810 <entry>Source Encoding
</entry>
1811 <entry>Destination Encoding
</entry>
1817 <entry><literal>ascii_to_mic
</literal></entry>
1818 <entry><literal>SQL_ASCII
</literal></entry>
1819 <entry><literal>MULE_INTERNAL
</literal></entry>
1823 <entry><literal>ascii_to_utf8
</literal></entry>
1824 <entry><literal>SQL_ASCII
</literal></entry>
1825 <entry><literal>UTF8
</literal></entry>
1829 <entry><literal>big5_to_euc_tw
</literal></entry>
1830 <entry><literal>BIG5
</literal></entry>
1831 <entry><literal>EUC_TW
</literal></entry>
1835 <entry><literal>big5_to_mic
</literal></entry>
1836 <entry><literal>BIG5
</literal></entry>
1837 <entry><literal>MULE_INTERNAL
</literal></entry>
1841 <entry><literal>big5_to_utf8
</literal></entry>
1842 <entry><literal>BIG5
</literal></entry>
1843 <entry><literal>UTF8
</literal></entry>
1847 <entry><literal>euc_cn_to_mic
</literal></entry>
1848 <entry><literal>EUC_CN
</literal></entry>
1849 <entry><literal>MULE_INTERNAL
</literal></entry>
1853 <entry><literal>euc_cn_to_utf8
</literal></entry>
1854 <entry><literal>EUC_CN
</literal></entry>
1855 <entry><literal>UTF8
</literal></entry>
1859 <entry><literal>euc_jp_to_mic
</literal></entry>
1860 <entry><literal>EUC_JP
</literal></entry>
1861 <entry><literal>MULE_INTERNAL
</literal></entry>
1865 <entry><literal>euc_jp_to_sjis
</literal></entry>
1866 <entry><literal>EUC_JP
</literal></entry>
1867 <entry><literal>SJIS
</literal></entry>
1871 <entry><literal>euc_jp_to_utf8
</literal></entry>
1872 <entry><literal>EUC_JP
</literal></entry>
1873 <entry><literal>UTF8
</literal></entry>
1877 <entry><literal>euc_kr_to_mic
</literal></entry>
1878 <entry><literal>EUC_KR
</literal></entry>
1879 <entry><literal>MULE_INTERNAL
</literal></entry>
1883 <entry><literal>euc_kr_to_utf8
</literal></entry>
1884 <entry><literal>EUC_KR
</literal></entry>
1885 <entry><literal>UTF8
</literal></entry>
1889 <entry><literal>euc_tw_to_big5
</literal></entry>
1890 <entry><literal>EUC_TW
</literal></entry>
1891 <entry><literal>BIG5
</literal></entry>
1895 <entry><literal>euc_tw_to_mic
</literal></entry>
1896 <entry><literal>EUC_TW
</literal></entry>
1897 <entry><literal>MULE_INTERNAL
</literal></entry>
1901 <entry><literal>euc_tw_to_utf8
</literal></entry>
1902 <entry><literal>EUC_TW
</literal></entry>
1903 <entry><literal>UTF8
</literal></entry>
1907 <entry><literal>gb18030_to_utf8
</literal></entry>
1908 <entry><literal>GB18030
</literal></entry>
1909 <entry><literal>UTF8
</literal></entry>
1913 <entry><literal>gbk_to_utf8
</literal></entry>
1914 <entry><literal>GBK
</literal></entry>
1915 <entry><literal>UTF8
</literal></entry>
1919 <entry><literal>iso_8859_10_to_utf8
</literal></entry>
1920 <entry><literal>LATIN6
</literal></entry>
1921 <entry><literal>UTF8
</literal></entry>
1925 <entry><literal>iso_8859_13_to_utf8
</literal></entry>
1926 <entry><literal>LATIN7
</literal></entry>
1927 <entry><literal>UTF8
</literal></entry>
1931 <entry><literal>iso_8859_14_to_utf8
</literal></entry>
1932 <entry><literal>LATIN8
</literal></entry>
1933 <entry><literal>UTF8
</literal></entry>
1937 <entry><literal>iso_8859_15_to_utf8
</literal></entry>
1938 <entry><literal>LATIN9
</literal></entry>
1939 <entry><literal>UTF8
</literal></entry>
1943 <entry><literal>iso_8859_16_to_utf8
</literal></entry>
1944 <entry><literal>LATIN10
</literal></entry>
1945 <entry><literal>UTF8
</literal></entry>
1949 <entry><literal>iso_8859_1_to_mic
</literal></entry>
1950 <entry><literal>LATIN1
</literal></entry>
1951 <entry><literal>MULE_INTERNAL
</literal></entry>
1955 <entry><literal>iso_8859_1_to_utf8
</literal></entry>
1956 <entry><literal>LATIN1
</literal></entry>
1957 <entry><literal>UTF8
</literal></entry>
1961 <entry><literal>iso_8859_2_to_mic
</literal></entry>
1962 <entry><literal>LATIN2
</literal></entry>
1963 <entry><literal>MULE_INTERNAL
</literal></entry>
1967 <entry><literal>iso_8859_2_to_utf8
</literal></entry>
1968 <entry><literal>LATIN2
</literal></entry>
1969 <entry><literal>UTF8
</literal></entry>
1973 <entry><literal>iso_8859_2_to_windows_1250
</literal></entry>
1974 <entry><literal>LATIN2
</literal></entry>
1975 <entry><literal>WIN1250
</literal></entry>
1979 <entry><literal>iso_8859_3_to_mic
</literal></entry>
1980 <entry><literal>LATIN3
</literal></entry>
1981 <entry><literal>MULE_INTERNAL
</literal></entry>
1985 <entry><literal>iso_8859_3_to_utf8
</literal></entry>
1986 <entry><literal>LATIN3
</literal></entry>
1987 <entry><literal>UTF8
</literal></entry>
1991 <entry><literal>iso_8859_4_to_mic
</literal></entry>
1992 <entry><literal>LATIN4
</literal></entry>
1993 <entry><literal>MULE_INTERNAL
</literal></entry>
1997 <entry><literal>iso_8859_4_to_utf8
</literal></entry>
1998 <entry><literal>LATIN4
</literal></entry>
1999 <entry><literal>UTF8
</literal></entry>
2003 <entry><literal>iso_8859_5_to_koi8_r
</literal></entry>
2004 <entry><literal>ISO_8859_5
</literal></entry>
2005 <entry><literal>KOI8R
</literal></entry>
2009 <entry><literal>iso_8859_5_to_mic
</literal></entry>
2010 <entry><literal>ISO_8859_5
</literal></entry>
2011 <entry><literal>MULE_INTERNAL
</literal></entry>
2015 <entry><literal>iso_8859_5_to_utf8
</literal></entry>
2016 <entry><literal>ISO_8859_5
</literal></entry>
2017 <entry><literal>UTF8
</literal></entry>
2021 <entry><literal>iso_8859_5_to_windows_1251
</literal></entry>
2022 <entry><literal>ISO_8859_5
</literal></entry>
2023 <entry><literal>WIN1251
</literal></entry>
2027 <entry><literal>iso_8859_5_to_windows_866
</literal></entry>
2028 <entry><literal>ISO_8859_5
</literal></entry>
2029 <entry><literal>WIN866
</literal></entry>
2033 <entry><literal>iso_8859_6_to_utf8
</literal></entry>
2034 <entry><literal>ISO_8859_6
</literal></entry>
2035 <entry><literal>UTF8
</literal></entry>
2039 <entry><literal>iso_8859_7_to_utf8
</literal></entry>
2040 <entry><literal>ISO_8859_7
</literal></entry>
2041 <entry><literal>UTF8
</literal></entry>
2045 <entry><literal>iso_8859_8_to_utf8
</literal></entry>
2046 <entry><literal>ISO_8859_8
</literal></entry>
2047 <entry><literal>UTF8
</literal></entry>
2051 <entry><literal>iso_8859_9_to_utf8
</literal></entry>
2052 <entry><literal>LATIN5
</literal></entry>
2053 <entry><literal>UTF8
</literal></entry>
2057 <entry><literal>johab_to_utf8
</literal></entry>
2058 <entry><literal>JOHAB
</literal></entry>
2059 <entry><literal>UTF8
</literal></entry>
2063 <entry><literal>koi8_r_to_iso_8859_5
</literal></entry>
2064 <entry><literal>KOI8R
</literal></entry>
2065 <entry><literal>ISO_8859_5
</literal></entry>
2069 <entry><literal>koi8_r_to_mic
</literal></entry>
2070 <entry><literal>KOI8R
</literal></entry>
2071 <entry><literal>MULE_INTERNAL
</literal></entry>
2075 <entry><literal>koi8_r_to_utf8
</literal></entry>
2076 <entry><literal>KOI8R
</literal></entry>
2077 <entry><literal>UTF8
</literal></entry>
2081 <entry><literal>koi8_r_to_windows_1251
</literal></entry>
2082 <entry><literal>KOI8R
</literal></entry>
2083 <entry><literal>WIN1251
</literal></entry>
2087 <entry><literal>koi8_r_to_windows_866
</literal></entry>
2088 <entry><literal>KOI8R
</literal></entry>
2089 <entry><literal>WIN866
</literal></entry>
2093 <entry><literal>koi8_u_to_utf8
</literal></entry>
2094 <entry><literal>KOI8U
</literal></entry>
2095 <entry><literal>UTF8
</literal></entry>
2099 <entry><literal>mic_to_ascii
</literal></entry>
2100 <entry><literal>MULE_INTERNAL
</literal></entry>
2101 <entry><literal>SQL_ASCII
</literal></entry>
2105 <entry><literal>mic_to_big5
</literal></entry>
2106 <entry><literal>MULE_INTERNAL
</literal></entry>
2107 <entry><literal>BIG5
</literal></entry>
2111 <entry><literal>mic_to_euc_cn
</literal></entry>
2112 <entry><literal>MULE_INTERNAL
</literal></entry>
2113 <entry><literal>EUC_CN
</literal></entry>
2117 <entry><literal>mic_to_euc_jp
</literal></entry>
2118 <entry><literal>MULE_INTERNAL
</literal></entry>
2119 <entry><literal>EUC_JP
</literal></entry>
2123 <entry><literal>mic_to_euc_kr
</literal></entry>
2124 <entry><literal>MULE_INTERNAL
</literal></entry>
2125 <entry><literal>EUC_KR
</literal></entry>
2129 <entry><literal>mic_to_euc_tw
</literal></entry>
2130 <entry><literal>MULE_INTERNAL
</literal></entry>
2131 <entry><literal>EUC_TW
</literal></entry>
2135 <entry><literal>mic_to_iso_8859_1
</literal></entry>
2136 <entry><literal>MULE_INTERNAL
</literal></entry>
2137 <entry><literal>LATIN1
</literal></entry>
2141 <entry><literal>mic_to_iso_8859_2
</literal></entry>
2142 <entry><literal>MULE_INTERNAL
</literal></entry>
2143 <entry><literal>LATIN2
</literal></entry>
2147 <entry><literal>mic_to_iso_8859_3
</literal></entry>
2148 <entry><literal>MULE_INTERNAL
</literal></entry>
2149 <entry><literal>LATIN3
</literal></entry>
2153 <entry><literal>mic_to_iso_8859_4
</literal></entry>
2154 <entry><literal>MULE_INTERNAL
</literal></entry>
2155 <entry><literal>LATIN4
</literal></entry>
2159 <entry><literal>mic_to_iso_8859_5
</literal></entry>
2160 <entry><literal>MULE_INTERNAL
</literal></entry>
2161 <entry><literal>ISO_8859_5
</literal></entry>
2165 <entry><literal>mic_to_koi8_r
</literal></entry>
2166 <entry><literal>MULE_INTERNAL
</literal></entry>
2167 <entry><literal>KOI8R
</literal></entry>
2171 <entry><literal>mic_to_sjis
</literal></entry>
2172 <entry><literal>MULE_INTERNAL
</literal></entry>
2173 <entry><literal>SJIS
</literal></entry>
2177 <entry><literal>mic_to_windows_1250
</literal></entry>
2178 <entry><literal>MULE_INTERNAL
</literal></entry>
2179 <entry><literal>WIN1250
</literal></entry>
2183 <entry><literal>mic_to_windows_1251
</literal></entry>
2184 <entry><literal>MULE_INTERNAL
</literal></entry>
2185 <entry><literal>WIN1251
</literal></entry>
2189 <entry><literal>mic_to_windows_866
</literal></entry>
2190 <entry><literal>MULE_INTERNAL
</literal></entry>
2191 <entry><literal>WIN866
</literal></entry>
2195 <entry><literal>sjis_to_euc_jp
</literal></entry>
2196 <entry><literal>SJIS
</literal></entry>
2197 <entry><literal>EUC_JP
</literal></entry>
2201 <entry><literal>sjis_to_mic
</literal></entry>
2202 <entry><literal>SJIS
</literal></entry>
2203 <entry><literal>MULE_INTERNAL
</literal></entry>
2207 <entry><literal>sjis_to_utf8
</literal></entry>
2208 <entry><literal>SJIS
</literal></entry>
2209 <entry><literal>UTF8
</literal></entry>
2213 <entry><literal>tcvn_to_utf8
</literal></entry>
2214 <entry><literal>WIN1258
</literal></entry>
2215 <entry><literal>UTF8
</literal></entry>
2219 <entry><literal>uhc_to_utf8
</literal></entry>
2220 <entry><literal>UHC
</literal></entry>
2221 <entry><literal>UTF8
</literal></entry>
2225 <entry><literal>utf8_to_ascii
</literal></entry>
2226 <entry><literal>UTF8
</literal></entry>
2227 <entry><literal>SQL_ASCII
</literal></entry>
2231 <entry><literal>utf8_to_big5
</literal></entry>
2232 <entry><literal>UTF8
</literal></entry>
2233 <entry><literal>BIG5
</literal></entry>
2237 <entry><literal>utf8_to_euc_cn
</literal></entry>
2238 <entry><literal>UTF8
</literal></entry>
2239 <entry><literal>EUC_CN
</literal></entry>
2243 <entry><literal>utf8_to_euc_jp
</literal></entry>
2244 <entry><literal>UTF8
</literal></entry>
2245 <entry><literal>EUC_JP
</literal></entry>
2249 <entry><literal>utf8_to_euc_kr
</literal></entry>
2250 <entry><literal>UTF8
</literal></entry>
2251 <entry><literal>EUC_KR
</literal></entry>
2255 <entry><literal>utf8_to_euc_tw
</literal></entry>
2256 <entry><literal>UTF8
</literal></entry>
2257 <entry><literal>EUC_TW
</literal></entry>
2261 <entry><literal>utf8_to_gb18030
</literal></entry>
2262 <entry><literal>UTF8
</literal></entry>
2263 <entry><literal>GB18030
</literal></entry>
2267 <entry><literal>utf8_to_gbk
</literal></entry>
2268 <entry><literal>UTF8
</literal></entry>
2269 <entry><literal>GBK
</literal></entry>
2273 <entry><literal>utf8_to_iso_8859_1
</literal></entry>
2274 <entry><literal>UTF8
</literal></entry>
2275 <entry><literal>LATIN1
</literal></entry>
2279 <entry><literal>utf8_to_iso_8859_10
</literal></entry>
2280 <entry><literal>UTF8
</literal></entry>
2281 <entry><literal>LATIN6
</literal></entry>
2285 <entry><literal>utf8_to_iso_8859_13
</literal></entry>
2286 <entry><literal>UTF8
</literal></entry>
2287 <entry><literal>LATIN7
</literal></entry>
2291 <entry><literal>utf8_to_iso_8859_14
</literal></entry>
2292 <entry><literal>UTF8
</literal></entry>
2293 <entry><literal>LATIN8
</literal></entry>
2297 <entry><literal>utf8_to_iso_8859_15
</literal></entry>
2298 <entry><literal>UTF8
</literal></entry>
2299 <entry><literal>LATIN9
</literal></entry>
2303 <entry><literal>utf8_to_iso_8859_16
</literal></entry>
2304 <entry><literal>UTF8
</literal></entry>
2305 <entry><literal>LATIN10
</literal></entry>
2309 <entry><literal>utf8_to_iso_8859_2
</literal></entry>
2310 <entry><literal>UTF8
</literal></entry>
2311 <entry><literal>LATIN2
</literal></entry>
2315 <entry><literal>utf8_to_iso_8859_3
</literal></entry>
2316 <entry><literal>UTF8
</literal></entry>
2317 <entry><literal>LATIN3
</literal></entry>
2321 <entry><literal>utf8_to_iso_8859_4
</literal></entry>
2322 <entry><literal>UTF8
</literal></entry>
2323 <entry><literal>LATIN4
</literal></entry>
2327 <entry><literal>utf8_to_iso_8859_5
</literal></entry>
2328 <entry><literal>UTF8
</literal></entry>
2329 <entry><literal>ISO_8859_5
</literal></entry>
2333 <entry><literal>utf8_to_iso_8859_6
</literal></entry>
2334 <entry><literal>UTF8
</literal></entry>
2335 <entry><literal>ISO_8859_6
</literal></entry>
2339 <entry><literal>utf8_to_iso_8859_7
</literal></entry>
2340 <entry><literal>UTF8
</literal></entry>
2341 <entry><literal>ISO_8859_7
</literal></entry>
2345 <entry><literal>utf8_to_iso_8859_8
</literal></entry>
2346 <entry><literal>UTF8
</literal></entry>
2347 <entry><literal>ISO_8859_8
</literal></entry>
2351 <entry><literal>utf8_to_iso_8859_9
</literal></entry>
2352 <entry><literal>UTF8
</literal></entry>
2353 <entry><literal>LATIN5
</literal></entry>
2357 <entry><literal>utf8_to_johab
</literal></entry>
2358 <entry><literal>UTF8
</literal></entry>
2359 <entry><literal>JOHAB
</literal></entry>
2363 <entry><literal>utf8_to_koi8_r
</literal></entry>
2364 <entry><literal>UTF8
</literal></entry>
2365 <entry><literal>KOI8R
</literal></entry>
2369 <entry><literal>utf8_to_koi8_u
</literal></entry>
2370 <entry><literal>UTF8
</literal></entry>
2371 <entry><literal>KOI8U
</literal></entry>
2375 <entry><literal>utf8_to_sjis
</literal></entry>
2376 <entry><literal>UTF8
</literal></entry>
2377 <entry><literal>SJIS
</literal></entry>
2381 <entry><literal>utf8_to_tcvn
</literal></entry>
2382 <entry><literal>UTF8
</literal></entry>
2383 <entry><literal>WIN1258
</literal></entry>
2387 <entry><literal>utf8_to_uhc
</literal></entry>
2388 <entry><literal>UTF8
</literal></entry>
2389 <entry><literal>UHC
</literal></entry>
2393 <entry><literal>utf8_to_windows_1250
</literal></entry>
2394 <entry><literal>UTF8
</literal></entry>
2395 <entry><literal>WIN1250
</literal></entry>
2399 <entry><literal>utf8_to_windows_1251
</literal></entry>
2400 <entry><literal>UTF8
</literal></entry>
2401 <entry><literal>WIN1251
</literal></entry>
2405 <entry><literal>utf8_to_windows_1252
</literal></entry>
2406 <entry><literal>UTF8
</literal></entry>
2407 <entry><literal>WIN1252
</literal></entry>
2411 <entry><literal>utf8_to_windows_1253
</literal></entry>
2412 <entry><literal>UTF8
</literal></entry>
2413 <entry><literal>WIN1253
</literal></entry>
2417 <entry><literal>utf8_to_windows_1254
</literal></entry>
2418 <entry><literal>UTF8
</literal></entry>
2419 <entry><literal>WIN1254
</literal></entry>
2423 <entry><literal>utf8_to_windows_1255
</literal></entry>
2424 <entry><literal>UTF8
</literal></entry>
2425 <entry><literal>WIN1255
</literal></entry>
2429 <entry><literal>utf8_to_windows_1256
</literal></entry>
2430 <entry><literal>UTF8
</literal></entry>
2431 <entry><literal>WIN1256
</literal></entry>
2435 <entry><literal>utf8_to_windows_1257
</literal></entry>
2436 <entry><literal>UTF8
</literal></entry>
2437 <entry><literal>WIN1257
</literal></entry>
2441 <entry><literal>utf8_to_windows_866
</literal></entry>
2442 <entry><literal>UTF8
</literal></entry>
2443 <entry><literal>WIN866
</literal></entry>
2447 <entry><literal>utf8_to_windows_874
</literal></entry>
2448 <entry><literal>UTF8
</literal></entry>
2449 <entry><literal>WIN874
</literal></entry>
2453 <entry><literal>windows_1250_to_iso_8859_2
</literal></entry>
2454 <entry><literal>WIN1250
</literal></entry>
2455 <entry><literal>LATIN2
</literal></entry>
2459 <entry><literal>windows_1250_to_mic
</literal></entry>
2460 <entry><literal>WIN1250
</literal></entry>
2461 <entry><literal>MULE_INTERNAL
</literal></entry>
2465 <entry><literal>windows_1250_to_utf8
</literal></entry>
2466 <entry><literal>WIN1250
</literal></entry>
2467 <entry><literal>UTF8
</literal></entry>
2471 <entry><literal>windows_1251_to_iso_8859_5
</literal></entry>
2472 <entry><literal>WIN1251
</literal></entry>
2473 <entry><literal>ISO_8859_5
</literal></entry>
2477 <entry><literal>windows_1251_to_koi8_r
</literal></entry>
2478 <entry><literal>WIN1251
</literal></entry>
2479 <entry><literal>KOI8R
</literal></entry>
2483 <entry><literal>windows_1251_to_mic
</literal></entry>
2484 <entry><literal>WIN1251
</literal></entry>
2485 <entry><literal>MULE_INTERNAL
</literal></entry>
2489 <entry><literal>windows_1251_to_utf8
</literal></entry>
2490 <entry><literal>WIN1251
</literal></entry>
2491 <entry><literal>UTF8
</literal></entry>
2495 <entry><literal>windows_1251_to_windows_866
</literal></entry>
2496 <entry><literal>WIN1251
</literal></entry>
2497 <entry><literal>WIN866
</literal></entry>
2501 <entry><literal>windows_1252_to_utf8
</literal></entry>
2502 <entry><literal>WIN1252
</literal></entry>
2503 <entry><literal>UTF8
</literal></entry>
2507 <entry><literal>windows_1256_to_utf8
</literal></entry>
2508 <entry><literal>WIN1256
</literal></entry>
2509 <entry><literal>UTF8
</literal></entry>
2513 <entry><literal>windows_866_to_iso_8859_5
</literal></entry>
2514 <entry><literal>WIN866
</literal></entry>
2515 <entry><literal>ISO_8859_5
</literal></entry>
2519 <entry><literal>windows_866_to_koi8_r
</literal></entry>
2520 <entry><literal>WIN866
</literal></entry>
2521 <entry><literal>KOI8R
</literal></entry>
2525 <entry><literal>windows_866_to_mic
</literal></entry>
2526 <entry><literal>WIN866
</literal></entry>
2527 <entry><literal>MULE_INTERNAL
</literal></entry>
2531 <entry><literal>windows_866_to_utf8
</literal></entry>
2532 <entry><literal>WIN866
</literal></entry>
2533 <entry><literal>UTF8
</literal></entry>
2537 <entry><literal>windows_866_to_windows_1251
</literal></entry>
2538 <entry><literal>WIN866
</literal></entry>
2539 <entry><literal>WIN
</literal></entry>
2543 <entry><literal>windows_874_to_utf8
</literal></entry>
2544 <entry><literal>WIN874
</literal></entry>
2545 <entry><literal>UTF8
</literal></entry>
2549 <entry><literal>euc_jis_2004_to_utf8
</literal></entry>
2550 <entry><literal>EUC_JIS_2004
</literal></entry>
2551 <entry><literal>UTF8
</literal></entry>
2555 <entry><literal>ut8_to_euc_jis_2004
</literal></entry>
2556 <entry><literal>UTF8
</literal></entry>
2557 <entry><literal>EUC_JIS_2004
</literal></entry>
2561 <entry><literal>shift_jis_2004_to_utf8
</literal></entry>
2562 <entry><literal>SHIFT_JIS_2004
</literal></entry>
2563 <entry><literal>UTF8
</literal></entry>
2567 <entry><literal>ut8_to_shift_jis_2004
</literal></entry>
2568 <entry><literal>UTF8
</literal></entry>
2569 <entry><literal>SHIFT_JIS_2004
</literal></entry>
2573 <entry><literal>euc_jis_2004_to_shift_jis_2004
</literal></entry>
2574 <entry><literal>EUC_JIS_2004
</literal></entry>
2575 <entry><literal>SHIFT_JIS_2004
</literal></entry>
2579 <entry><literal>shift_jis_2004_to_euc_jis_2004
</literal></entry>
2580 <entry><literal>SHIFT_JIS_2004
</literal></entry>
2581 <entry><literal>EUC_JIS_2004
</literal></entry>
2591 <sect1 id=
"functions-binarystring">
2592 <title>Binary String Functions and Operators
</title>
2594 <indexterm zone=
"functions-binarystring">
2595 <primary>binary data
</primary>
2596 <secondary>functions
</secondary>
2600 This section describes functions and operators for examining and
2601 manipulating values of type
<type>bytea
</type>.
2605 <acronym>SQL
</acronym> defines some string functions that use
2606 key words, rather than commas, to separate
2607 arguments. Details are in
2608 <xref linkend=
"functions-binarystring-sql">.
2609 <productname>PostgreSQL<
/> also provides versions of these functions
2610 that use the regular function invocation syntax
2611 (see
<xref linkend=
"functions-binarystring-other">).
2614 <table id=
"functions-binarystring-sql">
2615 <title><acronym>SQL
</acronym> Binary String Functions and Operators
</title>
2619 <entry>Function
</entry>
2620 <entry>Return Type
</entry>
2621 <entry>Description
</entry>
2622 <entry>Example
</entry>
2623 <entry>Result
</entry>
2629 <entry><literal><parameter>string
</parameter> <literal>||
</literal>
2630 <parameter>string
</parameter></literal></entry>
2631 <entry> <type>bytea
</type> </entry>
2633 String concatenation
2635 <primary>binary string
</primary>
2636 <secondary>concatenation
</secondary>
2639 <entry><literal>E'\\\\Post'::bytea || E'\\
047gres\\
000'::bytea
</literal></entry>
2640 <entry><literal>\\Post'gres\
000</literal></entry>
2644 <entry><function>get_bit
</function>(
<parameter>string
</parameter>,
<parameter>offset
</parameter>)
</entry>
2645 <entry><type>int
</type></entry>
2647 Extract bit from string
2649 <primary>get_bit
</primary>
2652 <entry><literal>get_bit(E'Th\\
000omas'::bytea,
45)
</literal></entry>
2653 <entry><literal>1</literal></entry>
2657 <entry><function>get_byte
</function>(
<parameter>string
</parameter>,
<parameter>offset
</parameter>)
</entry>
2658 <entry><type>int
</type></entry>
2660 Extract byte from string
2662 <primary>get_byte
</primary>
2665 <entry><literal>get_byte(E'Th\\
000omas'::bytea,
4)
</literal></entry>
2666 <entry><literal>109</literal></entry>
2670 <entry><literal><function>octet_length
</function>(
<parameter>string
</parameter>)
</literal></entry>
2671 <entry><type>int
</type></entry>
2672 <entry>Number of bytes in binary string
</entry>
2673 <entry><literal>octet_length(E'jo\\
000se'::bytea)
</literal></entry>
2674 <entry><literal>5</literal></entry>
2678 <entry><literal><function>position
</function>(
<parameter>substring
</parameter> in
<parameter>string
</parameter>)
</literal></entry>
2679 <entry><type>int
</type></entry>
2680 <entry>Location of specified substring
</entry>
2681 <entry><literal>position(E'\\
000om'::bytea in E'Th\\
000omas'::bytea)
</literal></entry>
2682 <entry><literal>3</literal></entry>
2686 <entry><function>set_bit
</function>(
<parameter>string
</parameter>,
2687 <parameter>offset
</parameter>,
<parameter>newvalue<
/>)
</entry>
2688 <entry><type>bytea
</type></entry>
2692 <primary>set_bit
</primary>
2695 <entry><literal>set_bit(E'Th\\
000omas'::bytea,
45,
0)
</literal></entry>
2696 <entry><literal>Th\
000omAs
</literal></entry>
2700 <entry><function>set_byte
</function>(
<parameter>string
</parameter>,
2701 <parameter>offset
</parameter>,
<parameter>newvalue<
/>)
</entry>
2702 <entry><type>bytea
</type></entry>
2706 <primary>set_byte
</primary>
2709 <entry><literal>set_byte(E'Th\\
000omas'::bytea,
4,
64)
</literal></entry>
2710 <entry><literal>Th\
000o@as
</literal></entry>
2714 <entry><literal><function>substring
</function>(
<parameter>string
</parameter> <optional>from
<type>int
</type></optional> <optional>for
<type>int
</type></optional>)
</literal></entry>
2715 <entry><type>bytea
</type></entry>
2719 <primary>substring
</primary>
2722 <entry><literal>substring(E'Th\\
000omas'::bytea from
2 for
3)
</literal></entry>
2723 <entry><literal>h\
000o
</literal></entry>
2728 <literal><function>trim
</function>(
<optional>both
</optional>
2729 <parameter>bytes
</parameter> from
2730 <parameter>string
</parameter>)
</literal>
2732 <entry><type>bytea
</type></entry>
2734 Remove the longest string containing only the bytes in
2735 <parameter>bytes
</parameter> from the start
2736 and end of
<parameter>string
</parameter>
2738 <entry><literal>trim(E'\\
000'::bytea from E'\\
000Tom\\
000'::bytea)
</literal></entry>
2739 <entry><literal>Tom
</literal></entry>
2746 Additional binary string manipulation functions are available and
2747 are listed in
<xref linkend=
"functions-binarystring-other">. Some
2748 of them are used internally to implement the
2749 <acronym>SQL
</acronym>-standard string functions listed in
<xref
2750 linkend=
"functions-binarystring-sql">.
2753 <table id=
"functions-binarystring-other">
2754 <title>Other Binary String Functions
</title>
2758 <entry>Function
</entry>
2759 <entry>Return Type
</entry>
2760 <entry>Description
</entry>
2761 <entry>Example
</entry>
2762 <entry>Result
</entry>
2768 <entry><literal><function>btrim
</function>(
<parameter>string
</parameter>
2769 <type>bytea
</type>,
<parameter>bytes
</parameter> <type>bytea
</type>)
</literal></entry>
2770 <entry><type>bytea
</type></entry>
2772 Remove the longest string consisting only of bytes
2773 in
<parameter>bytes
</parameter> from the start and end of
2774 <parameter>string
</parameter>
2776 <entry><literal>btrim(E'\\
000trim\\
000'::bytea, E'\\
000'::bytea)
</literal></entry>
2777 <entry><literal>trim
</literal></entry>
2782 <literal><function>decode
</function>(
<parameter>string
</parameter> <type>text
</type>,
2783 <parameter>type
</parameter> <type>text
</type>)
</literal>
2785 <entry><type>bytea
</type></entry>
2787 Decode binary string from
<parameter>string
</parameter> previously
2788 encoded with
<function>encode<
/>. Parameter type is same as in
<function>encode<
/>.
2790 <entry><literal>decode(E'
123\\
000456', 'escape')
</literal></entry>
2791 <entry><literal>123\
000456</literal></entry>
2796 <literal><function>encode
</function>(
<parameter>string
</parameter> <type>bytea
</type>,
2797 <parameter>type
</parameter> <type>text
</type>)
</literal>
2799 <entry><type>text
</type></entry>
2801 Encode binary string to
<acronym>ASCII
</acronym>-only representation. Supported
2802 types are:
<literal>base64<
/>,
<literal>hex<
/>,
<literal>escape<
/>.
2804 <entry><literal>encode(E'
123\\
000456'::bytea, 'escape')
</literal></entry>
2805 <entry><literal>123\
000456</literal></entry>
2809 <entry><literal><function>length
</function>(
<parameter>string
</parameter>)
</literal></entry>
2810 <entry><type>int
</type></entry>
2812 Length of binary string
2814 <primary>binary string
</primary>
2815 <secondary>length
</secondary>
2818 <primary>length
</primary>
2819 <secondary sortas=
"binary string">of a binary string
</secondary>
2820 <see>binary strings, length
</see>
2823 <entry><literal>length(E'jo\\
000se'::bytea)
</literal></entry>
2824 <entry><literal>5</literal></entry>
2828 <entry><literal><function>md5
</function>(
<parameter>string
</parameter>)
</literal></entry>
2829 <entry><type>text
</type></entry>
2831 Calculates the MD5 hash of
<parameter>string
</parameter>,
2832 returning the result in hexadecimal
2834 <entry><literal>md5(E'Th\\
000omas'::bytea)
</literal></entry>
2835 <entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1
</literal></entry>
2844 <sect1 id=
"functions-bitstring">
2845 <title>Bit String Functions and Operators
</title>
2847 <indexterm zone=
"functions-bitstring">
2848 <primary>bit strings
</primary>
2849 <secondary>functions
</secondary>
2853 This section describes functions and operators for examining and
2854 manipulating bit strings, that is values of the types
2855 <type>bit
</type> and
<type>bit varying
</type>. Aside from the
2856 usual comparison operators, the operators
2857 shown in
<xref linkend=
"functions-bit-string-op-table"> can be used.
2858 Bit string operands of
<literal>&</literal>,
<literal>|
</literal>,
2859 and
<literal>#
</literal> must be of equal length. When bit
2860 shifting, the original length of the string is preserved, as shown
2864 <table id=
"functions-bit-string-op-table">
2865 <title>Bit String Operators
</title>
2870 <entry>Operator
</entry>
2871 <entry>Description
</entry>
2872 <entry>Example
</entry>
2873 <entry>Result
</entry>
2879 <entry> <literal>||
</literal> </entry>
2880 <entry>concatenation
</entry>
2881 <entry><literal>B'
10001' || B'
011'
</literal></entry>
2882 <entry><literal>10001011</literal></entry>
2886 <entry> <literal>&</literal> </entry>
2887 <entry>bitwise AND
</entry>
2888 <entry><literal>B'
10001'
& B'
01101'
</literal></entry>
2889 <entry><literal>00001</literal></entry>
2893 <entry> <literal>|
</literal> </entry>
2894 <entry>bitwise OR
</entry>
2895 <entry><literal>B'
10001' | B'
01101'
</literal></entry>
2896 <entry><literal>11101</literal></entry>
2900 <entry> <literal>#
</literal> </entry>
2901 <entry>bitwise XOR
</entry>
2902 <entry><literal>B'
10001' # B'
01101'
</literal></entry>
2903 <entry><literal>11100</literal></entry>
2907 <entry> <literal>~
</literal> </entry>
2908 <entry>bitwise NOT
</entry>
2909 <entry><literal>~ B'
10001'
</literal></entry>
2910 <entry><literal>01110</literal></entry>
2914 <entry> <literal><<</literal> </entry>
2915 <entry>bitwise shift left
</entry>
2916 <entry><literal>B'
10001'
<< 3</literal></entry>
2917 <entry><literal>01000</literal></entry>
2921 <entry> <literal>>></literal> </entry>
2922 <entry>bitwise shift right
</entry>
2923 <entry><literal>B'
10001'
>> 2</literal></entry>
2924 <entry><literal>00100</literal></entry>
2931 The following
<acronym>SQL
</acronym>-standard functions work on bit
2932 strings as well as character strings:
2933 <literal><function>length
</function></literal>,
2934 <literal><function>bit_length
</function></literal>,
2935 <literal><function>octet_length
</function></literal>,
2936 <literal><function>position
</function></literal>,
2937 <literal><function>substring
</function></literal>.
2941 In addition, it is possible to cast integral values to and from type
2945 44::bit(
10)
<lineannotation>0000101100</lineannotation>
2946 44::bit(
3)
<lineannotation>100</lineannotation>
2947 cast(-
44 as bit(
12))
<lineannotation>111111010100</lineannotation>
2948 '
1110'::bit(
4)::integer
<lineannotation>14</lineannotation>
2950 Note that casting to just
<quote>bit<
/> means casting to
2951 <literal>bit(
1)<
/>, and so will deliver only the least significant
2957 Prior to
<productname>PostgreSQL
</productname> 8.0, casting an
2958 integer to
<type>bit(n)<
/> would copy the leftmost
<literal>n<
/>
2959 bits of the integer, whereas now it copies the rightmost
<literal>n<
/>
2960 bits. Also, casting an integer to a bit string width wider than
2961 the integer itself will sign-extend on the left.
2968 <sect1 id=
"functions-matching">
2969 <title>Pattern Matching
</title>
2971 <indexterm zone=
"functions-matching">
2972 <primary>pattern matching
</primary>
2976 There are three separate approaches to pattern matching provided
2977 by
<productname>PostgreSQL
</productname>: the traditional
2978 <acronym>SQL
</acronym> <function>LIKE
</function> operator, the
2979 more recent
<function>SIMILAR TO
</function> operator (added in
2980 SQL:
1999), and
<acronym>POSIX
</acronym>-style regular
2981 expressions. Aside from the basic
<quote>does this string match
2982 this pattern?<
/> operators, functions are available to extract
2983 or replace matching substrings and to split a string at matching
2989 If you have pattern matching needs that go beyond this,
2990 consider writing a user-defined function in Perl or Tcl.
2994 <sect2 id=
"functions-like">
2995 <title><function>LIKE
</function></title>
2998 <primary>LIKE
</primary>
3002 <replaceable>string
</replaceable> LIKE
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
3003 <replaceable>string
</replaceable> NOT LIKE
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
3007 The
<function>LIKE
</function> expression returns true if the
3008 <replaceable>string
</replaceable> matches the supplied
3009 <replaceable>pattern
</replaceable>. (As
3010 expected, the
<function>NOT LIKE
</function> expression returns
3011 false if
<function>LIKE
</function> returns true, and vice versa.
3012 An equivalent expression is
3013 <literal>NOT (
<replaceable>string
</replaceable> LIKE
3014 <replaceable>pattern
</replaceable>)
</literal>.)
3018 If
<replaceable>pattern
</replaceable> does not contain percent
3019 signs or underscores, then the pattern only represents the string
3020 itself; in that case
<function>LIKE
</function> acts like the
3021 equals operator. An underscore (
<literal>_
</literal>) in
3022 <replaceable>pattern
</replaceable> stands for (matches) any single
3023 character; a percent sign (
<literal>%
</literal>) matches any sequence
3024 of zero or more characters.
3030 'abc' LIKE 'abc'
<lineannotation>true
</lineannotation>
3031 'abc' LIKE 'a%'
<lineannotation>true
</lineannotation>
3032 'abc' LIKE '_b_'
<lineannotation>true
</lineannotation>
3033 'abc' LIKE 'c'
<lineannotation>false
</lineannotation>
3038 <function>LIKE
</function> pattern matching always covers the entire
3039 string. Therefore, to match a sequence anywhere within a string, the
3040 pattern must start and end with a percent sign.
3044 To match a literal underscore or percent sign without matching
3045 other characters, the respective character in
3046 <replaceable>pattern
</replaceable> must be
3047 preceded by the escape character. The default escape
3048 character is the backslash but a different one can be selected by
3049 using the
<literal>ESCAPE
</literal> clause. To match the escape
3050 character itself, write two escape characters.
3054 Note that the backslash already has a special meaning in string literals,
3055 so to write a pattern constant that contains a backslash you must write two
3056 backslashes in an SQL statement (assuming escape string syntax is used, see
3057 <xref linkend=
"sql-syntax-strings">). Thus, writing a pattern that
3058 actually matches a literal backslash means writing four backslashes in the
3059 statement. You can avoid this by selecting a different escape character
3060 with
<literal>ESCAPE
</literal>; then a backslash is not special to
3061 <function>LIKE
</function> anymore. (But backslash is still special to the
3062 string literal parser, so you still need two of them to match a backslash.)
3066 It's also possible to select no escape character by writing
3067 <literal>ESCAPE ''
</literal>. This effectively disables the
3068 escape mechanism, which makes it impossible to turn off the
3069 special meaning of underscore and percent signs in the pattern.
3073 The key word
<token>ILIKE
</token> can be used instead of
3074 <token>LIKE
</token> to make the match case-insensitive according
3075 to the active locale. This is not in the
<acronym>SQL
</acronym> standard but is a
3076 <productname>PostgreSQL
</productname> extension.
3080 The operator
<literal>~~
</literal> is equivalent to
3081 <function>LIKE
</function>, and
<literal>~~*
</literal> corresponds to
3082 <function>ILIKE
</function>. There are also
3083 <literal>!~~
</literal> and
<literal>!~~*
</literal> operators that
3084 represent
<function>NOT LIKE
</function> and
<function>NOT
3085 ILIKE
</function>, respectively. All of these operators are
3086 <productname>PostgreSQL
</productname>-specific.
3091 <sect2 id=
"functions-similarto-regexp">
3092 <title><function>SIMILAR TO
</function> Regular Expressions
</title>
3095 <primary>regular expression
</primary>
3096 <!-- <seealso>pattern matching</seealso> breaks index build -->
3100 <primary>SIMILAR TO
</primary>
3103 <primary>substring
</primary>
3107 <replaceable>string
</replaceable> SIMILAR TO
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
3108 <replaceable>string
</replaceable> NOT SIMILAR TO
<replaceable>pattern
</replaceable> <optional>ESCAPE
<replaceable>escape-character
</replaceable></optional>
3112 The
<function>SIMILAR TO
</function> operator returns true or
3113 false depending on whether its pattern matches the given string.
3114 It is similar to
<function>LIKE
</function>, except that it
3115 interprets the pattern using the SQL standard's definition of a
3116 regular expression. SQL regular expressions are a curious cross
3117 between
<function>LIKE
</function> notation and common regular
3118 expression notation.
3122 Like
<function>LIKE
</function>, the
<function>SIMILAR TO
</function>
3123 operator succeeds only if its pattern matches the entire string;
3124 this is unlike common regular expression behavior where the pattern
3125 can match any part of the string.
3127 <function>LIKE
</function>,
<function>SIMILAR TO
</function> uses
3128 <literal>_<
/> and
<literal>%<
/> as wildcard characters denoting
3129 any single character and any string, respectively (these are
3130 comparable to
<literal>.<
/> and
<literal>.*<
/> in POSIX regular
3135 In addition to these facilities borrowed from
<function>LIKE
</function>,
3136 <function>SIMILAR TO
</function> supports these pattern-matching
3137 metacharacters borrowed from POSIX regular expressions:
3142 <literal>|
</literal> denotes alternation (either of two alternatives).
3147 <literal>*
</literal> denotes repetition of the previous item zero
3153 <literal>+
</literal> denotes repetition of the previous item one
3159 Parentheses
<literal>()
</literal> can be used to group items into
3160 a single logical item.
3165 A bracket expression
<literal>[...]
</literal> specifies a character
3166 class, just as in POSIX regular expressions.
3171 Notice that bounded repetition operators (
<literal>?<
/> and
3172 <literal>{...}<
/>) are not provided, though they exist in POSIX.
3173 Also, the period (
<literal>.<
/>) is not a metacharacter.
3177 As with
<function>LIKE<
/>, a backslash disables the special meaning
3178 of any of these metacharacters; or a different escape character can
3179 be specified with
<literal>ESCAPE<
/>.
3185 'abc' SIMILAR TO 'abc'
<lineannotation>true
</lineannotation>
3186 'abc' SIMILAR TO 'a'
<lineannotation>false
</lineannotation>
3187 'abc' SIMILAR TO '%(b|d)%'
<lineannotation>true
</lineannotation>
3188 'abc' SIMILAR TO '(b|c)%'
<lineannotation>false
</lineannotation>
3193 The
<function>substring<
/> function with three parameters,
3194 <function>substring(
<replaceable>string
</replaceable> from
3195 <replaceable>pattern
</replaceable> for
3196 <replaceable>escape-character
</replaceable>)
</function>, provides
3197 extraction of a substring that matches an SQL
3198 regular expression pattern. As with
<literal>SIMILAR TO<
/>, the
3199 specified pattern must match the entire data string, or else the
3200 function fails and returns null. To indicate the part of the
3201 pattern that should be returned on success, the pattern must contain
3202 two occurrences of the escape character followed by a double quote
3203 (
<literal>"</>). <!-- " font-lock sanity -->
3204 The text matching the portion of the pattern
3205 between these markers is returned.
3209 Some examples, with
<literal>#
"</> delimiting the return string:
3211 substring('foobar' from '%#"o_b#
"%' for '#') <lineannotation>oob</lineannotation>
3212 substring('foobar' from '#"o_b#
"%' for '#') <lineannotation>NULL</lineannotation>
3217 <sect2 id="functions-posix-regexp
">
3218 <title><acronym>POSIX</acronym> Regular Expressions</title>
3220 <indexterm zone="functions-posix-regexp
">
3221 <primary>regular expression</primary>
3222 <seealso>pattern matching</seealso>
3225 <primary>substring</primary>
3228 <primary>regexp_replace</primary>
3231 <primary>regexp_matches</primary>
3234 <primary>regexp_split_to_table</primary>
3237 <primary>regexp_split_to_array</primary>
3241 <xref linkend="functions-posix-table
"> lists the available
3242 operators for pattern matching using POSIX regular expressions.
3245 <table id="functions-posix-table
">
3246 <title>Regular Expression Match Operators</title>
3251 <entry>Operator</entry>
3252 <entry>Description</entry>
3253 <entry>Example</entry>
3259 <entry> <literal>~</literal> </entry>
3260 <entry>Matches regular expression, case sensitive</entry>
3261 <entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
3265 <entry> <literal>~*</literal> </entry>
3266 <entry>Matches regular expression, case insensitive</entry>
3267 <entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
3271 <entry> <literal>!~</literal> </entry>
3272 <entry>Does not match regular expression, case sensitive</entry>
3273 <entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
3277 <entry> <literal>!~*</literal> </entry>
3278 <entry>Does not match regular expression, case insensitive</entry>
3279 <entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
3286 <acronym>POSIX</acronym> regular expressions provide a more
3288 pattern matching than the <function>LIKE</function> and
3289 <function>SIMILAR TO</> operators.
3290 Many Unix tools such as <command>egrep</command>,
3291 <command>sed</command>, or <command>awk</command> use a pattern
3292 matching language that is similar to the one described here.
3296 A regular expression is a character sequence that is an
3297 abbreviated definition of a set of strings (a <firstterm>regular
3298 set</firstterm>). A string is said to match a regular expression
3299 if it is a member of the regular set described by the regular
3300 expression. As with <function>LIKE</function>, pattern characters
3301 match string characters exactly unless they are special characters
3302 in the regular expression language — but regular expressions use
3303 different special characters than <function>LIKE</function> does.
3304 Unlike <function>LIKE</function> patterns, a
3305 regular expression is allowed to match anywhere within a string, unless
3306 the regular expression is explicitly anchored to the beginning or
3313 'abc' ~ 'abc' <lineannotation>true</lineannotation>
3314 'abc' ~ '^a' <lineannotation>true</lineannotation>
3315 'abc' ~ '(b|d)' <lineannotation>true</lineannotation>
3316 'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
3321 The <acronym>POSIX</acronym> pattern language is described in much
3322 greater detail below.
3326 The <function>substring</> function with two parameters,
3327 <function>substring(<replaceable>string</replaceable> from
3328 <replaceable>pattern</replaceable>)</function>, provides extraction of a
3330 that matches a POSIX regular expression pattern. It returns null if
3331 there is no match, otherwise the portion of the text that matched the
3332 pattern. But if the pattern contains any parentheses, the portion
3333 of the text that matched the first parenthesized subexpression (the
3334 one whose left parenthesis comes first) is
3335 returned. You can put parentheses around the whole expression
3336 if you want to use parentheses within it without triggering this
3337 exception. If you need parentheses in the pattern before the
3338 subexpression you want to extract, see the non-capturing parentheses
3345 substring('foobar' from 'o.b') <lineannotation>oob</lineannotation>
3346 substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation>
3351 The <function>regexp_replace</> function provides substitution of
3352 new text for substrings that match POSIX regular expression patterns.
3354 <function>regexp_replace</function>(<replaceable>source</>,
3355 <replaceable>pattern</>, <replaceable>replacement</>
3356 <optional>, <replaceable>flags</> </optional>).
3357 The <replaceable>source</> string is returned unchanged if
3358 there is no match to the <replaceable>pattern</>. If there is a
3359 match, the <replaceable>source</> string is returned with the
3360 <replaceable>replacement</> string substituted for the matching
3361 substring. The <replaceable>replacement</> string can contain
3362 <literal>\</><replaceable>n</>, where <replaceable>n</> is <literal>1</>
3363 through <literal>9</>, to indicate that the source substring matching the
3364 <replaceable>n</>'th parenthesized subexpression of the pattern should be
3365 inserted, and it can contain <literal>\&</> to indicate that the
3366 substring matching the entire pattern should be inserted. Write
3367 <literal>\\</> if you need to put a literal backslash in the replacement
3368 text. (As always, remember to double backslashes written in literal
3369 constant strings, assuming escape string syntax is used.)
3370 The <replaceable>flags</> parameter is an optional text
3371 string containing zero or more single-letter flags that change the
3372 function's behavior. Flag <literal>i</> specifies case-insensitive
3373 matching, while flag <literal>g</> specifies replacement of each matching
3374 substring rather than only the first one. Other supported flags are
3375 described in <xref linkend="posix-embedded-options-table
">.
3381 regexp_replace('foobarbaz', 'b..', 'X')
3382 <lineannotation>fooXbaz</lineannotation>
3383 regexp_replace('foobarbaz', 'b..', 'X', 'g')
3384 <lineannotation>fooXX</lineannotation>
3385 regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
3386 <lineannotation>fooXarYXazY</lineannotation>
3391 The <function>regexp_matches</> function returns all of the captured
3392 substrings resulting from matching a POSIX regular expression pattern.
3394 <function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
3395 <optional>, <replaceable>flags</> </optional>).
3396 If there is no match to the <replaceable>pattern</>, the function returns
3397 no rows. If there is a match, the function returns a text array whose
3398 <replaceable>n</>'th element is the substring matching the
3399 <replaceable>n</>'th parenthesized subexpression of the pattern
3400 (not counting <quote>non-capturing</> parentheses; see below for
3401 details). If the pattern does not contain any parenthesized
3402 subexpressions, then the result is a single-element text array containing
3403 the substring matching the whole pattern.
3404 The <replaceable>flags</> parameter is an optional text
3405 string containing zero or more single-letter flags that change the
3406 function's behavior. Flag <literal>g</> causes the function to find
3407 each match in the string, not only the first one, and return a row for
3408 each such match. Other supported
3409 flags are described in <xref linkend="posix-embedded-options-table
">.
3415 SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
3421 SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
3428 SELECT regexp_matches('foobarbequebaz', 'barbeque');
3437 The <function>regexp_split_to_table</> function splits a string using a POSIX
3438 regular expression pattern as a delimiter. It has the syntax
3439 <function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
3440 <optional>, <replaceable>flags</> </optional>).
3441 If there is no match to the <replaceable>pattern</>, the function returns the
3442 <replaceable>string</>. If there is at least one match, for each match it returns
3443 the text from the end of the last match (or the beginning of the string)
3444 to the beginning of the match. When there are no more matches, it
3445 returns the text from the end of the last match to the end of the string.
3446 The <replaceable>flags</> parameter is an optional text string containing
3447 zero or more single-letter flags that change the function's behavior.
3448 <function>regexp_split_to_table</function> supports the flags described in
3449 <xref linkend="posix-embedded-options-table
">.
3453 The <function>regexp_split_to_array</> function behaves the same as
3454 <function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
3455 returns its result as an array of <type>text</>. It has the syntax
3456 <function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
3457 <optional>, <replaceable>flags</> </optional>).
3458 The parameters are the same as for <function>regexp_split_to_table</>.
3465 SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\s+') AS foo;
3479 SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
3480 regexp_split_to_array
3481 ------------------------------------------------
3482 {the,quick,brown,fox,jumped,over,the,lazy,dog}
3485 SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
3509 As the last example demonstrates, the regexp split functions ignore
3510 zero-length matches that occur at the start or end of the string
3511 or immediately after a previous match. This is contrary to the strict
3512 definition of regexp matching that is implemented by
3513 <function>regexp_matches</>, but is usually the most convenient behavior
3514 in practice. Other software systems such as Perl use similar definitions.
3517 <!-- derived from the re_syntax.n man page -->
3519 <sect3 id="posix-syntax-details
">
3520 <title>Regular Expression Details</title>
3523 <productname>PostgreSQL</productname>'s regular expressions are implemented
3524 using a software package written by Henry Spencer. Much of
3525 the description of regular expressions below is copied verbatim from his
3530 Regular expressions (<acronym>RE</acronym>s), as defined in
3531 <acronym>POSIX</acronym> 1003.2, come in two forms:
3532 <firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
3533 (roughly those of <command>egrep</command>), and
3534 <firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
3535 (roughly those of <command>ed</command>).
3536 <productname>PostgreSQL</productname> supports both forms, and
3537 also implements some extensions
3538 that are not in the POSIX standard, but have become widely used
3539 due to their availability in programming languages such as Perl and Tcl.
3540 <acronym>RE</acronym>s using these non-POSIX extensions are called
3541 <firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
3542 in this documentation. AREs are almost an exact superset of EREs,
3543 but BREs have several notational incompatibilities (as well as being
3545 We first describe the ARE and ERE forms, noting features that apply
3546 only to AREs, and then describe how BREs differ.
3551 The form of regular expressions accepted by
3552 <productname>PostgreSQL</> can be chosen by setting the <xref
3553 linkend="guc-regex-flavor
"> run-time parameter. The usual
3554 setting is <literal>advanced</>, but one might choose
3555 <literal>extended</> for backwards compatibility with
3556 pre-7.4 releases of <productname>PostgreSQL</>.
3561 A regular expression is defined as one or more
3562 <firstterm>branches</firstterm>, separated by
3563 <literal>|</literal>. It matches anything that matches one of the
3568 A branch is zero or more <firstterm>quantified atoms</> or
3569 <firstterm>constraints</>, concatenated.
3570 It matches a match for the first, followed by a match for the second, etc;
3571 an empty branch matches the empty string.
3575 A quantified atom is an <firstterm>atom</> possibly followed
3576 by a single <firstterm>quantifier</>.
3577 Without a quantifier, it matches a match for the atom.
3578 With a quantifier, it can match some number of matches of the atom.
3579 An <firstterm>atom</firstterm> can be any of the possibilities
3580 shown in <xref linkend="posix-atoms-table
">.
3581 The possible quantifiers and their meanings are shown in
3582 <xref linkend="posix-quantifiers-table
">.
3586 A <firstterm>constraint</> matches an empty string, but matches only when
3587 specific conditions are met. A constraint can be used where an atom
3588 could be used, except it cannot be followed by a quantifier.
3589 The simple constraints are shown in
3590 <xref linkend="posix-constraints-table
">;
3591 some more constraints are described later.
3595 <table id="posix-atoms-table
">
3596 <title>Regular Expression Atoms</title>
3602 <entry>Description</entry>
3608 <entry> <literal>(</><replaceable>re</><literal>)</> </entry>
3609 <entry> (where <replaceable>re</> is any regular expression)
3611 <replaceable>re</>, with the match noted for possible reporting </entry>
3615 <entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
3616 <entry> as above, but the match is not noted for reporting
3617 (a <quote>non-capturing</> set of parentheses)
3618 (AREs only) </entry>
3622 <entry> <literal>.</> </entry>
3623 <entry> matches any single character </entry>
3627 <entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
3628 <entry> a <firstterm>bracket expression</>,
3629 matching any one of the <replaceable>chars</> (see
3630 <xref linkend="posix-bracket-expressions
"> for more detail) </entry>
3634 <entry> <literal>\</><replaceable>k</> </entry>
3635 <entry> (where <replaceable>k</> is a non-alphanumeric character)
3636 matches that character taken as an ordinary character,
3637 e.g., <literal>\\</> matches a backslash character </entry>
3641 <entry> <literal>\</><replaceable>c</> </entry>
3642 <entry> where <replaceable>c</> is alphanumeric
3643 (possibly followed by other characters)
3644 is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences
">
3645 (AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
3649 <entry> <literal>{</> </entry>
3650 <entry> when followed by a character other than a digit,
3651 matches the left-brace character <literal>{</>;
3652 when followed by a digit, it is the beginning of a
3653 <replaceable>bound</> (see below) </entry>
3657 <entry> <replaceable>x</> </entry>
3658 <entry> where <replaceable>x</> is a single character with no other
3659 significance, matches that character </entry>
3666 An RE cannot end with <literal>\</>.
3671 Remember that the backslash (<literal>\</literal>) already has a special
3672 meaning in <productname>PostgreSQL</> string literals.
3673 To write a pattern constant that contains a backslash,
3674 you must write two backslashes in the statement, assuming escape
3675 string syntax is used (see <xref linkend="sql-syntax-strings
">).
3679 <table id="posix-quantifiers-table
">
3680 <title>Regular Expression Quantifiers</title>
3685 <entry>Quantifier</entry>
3686 <entry>Matches</entry>
3692 <entry> <literal>*</> </entry>
3693 <entry> a sequence of 0 or more matches of the atom </entry>
3697 <entry> <literal>+</> </entry>
3698 <entry> a sequence of 1 or more matches of the atom </entry>
3702 <entry> <literal>?</> </entry>
3703 <entry> a sequence of 0 or 1 matches of the atom </entry>
3707 <entry> <literal>{</><replaceable>m</><literal>}</> </entry>
3708 <entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
3712 <entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
3713 <entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
3718 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3719 <entry> a sequence of <replaceable>m</> through <replaceable>n</>
3720 (inclusive) matches of the atom; <replaceable>m</> cannot exceed
3721 <replaceable>n</> </entry>
3725 <entry> <literal>*?</> </entry>
3726 <entry> non-greedy version of <literal>*</> </entry>
3730 <entry> <literal>+?</> </entry>
3731 <entry> non-greedy version of <literal>+</> </entry>
3735 <entry> <literal>??</> </entry>
3736 <entry> non-greedy version of <literal>?</> </entry>
3740 <entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
3741 <entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
3745 <entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
3746 <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
3751 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
3752 <entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
3759 The forms using <literal>{</><replaceable>...</><literal>}</>
3760 are known as <firstterm>bounds</>.
3761 The numbers <replaceable>m</> and <replaceable>n</> within a bound are
3762 unsigned decimal integers with permissible values from 0 to 255 inclusive.
3766 <firstterm>Non-greedy</> quantifiers (available in AREs only) match the
3767 same possibilities as their corresponding normal (<firstterm>greedy</>)
3768 counterparts, but prefer the smallest number rather than the largest
3770 See <xref linkend="posix-matching-rules
"> for more detail.
3775 A quantifier cannot immediately follow another quantifier, e.g.,
3776 <literal>**</> is invalid.
3778 begin an expression or subexpression or follow
3779 <literal>^</literal> or <literal>|</literal>.
3783 <table id="posix-constraints-table
">
3784 <title>Regular Expression Constraints</title>
3789 <entry>Constraint</entry>
3790 <entry>Description</entry>
3796 <entry> <literal>^</> </entry>
3797 <entry> matches at the beginning of the string </entry>
3801 <entry> <literal>$</> </entry>
3802 <entry> matches at the end of the string </entry>
3806 <entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
3807 <entry> <firstterm>positive lookahead</> matches at any point
3808 where a substring matching <replaceable>re</> begins
3809 (AREs only) </entry>
3813 <entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
3814 <entry> <firstterm>negative lookahead</> matches at any point
3815 where no substring matching <replaceable>re</> begins
3816 (AREs only) </entry>
3823 Lookahead constraints cannot contain <firstterm>back references</>
3824 (see <xref linkend="posix-escape-sequences
">),
3825 and all parentheses within them are considered non-capturing.
3829 <sect3 id="posix-bracket-expressions
">
3830 <title>Bracket Expressions</title>
3833 A <firstterm>bracket expression</firstterm> is a list of
3834 characters enclosed in <literal>[]</literal>. It normally matches
3835 any single character from the list (but see below). If the list
3836 begins with <literal>^</literal>, it matches any single character
3837 <emphasis>not</> from the rest of the list.
3839 in the list are separated by <literal>-</literal>, this is
3840 shorthand for the full range of characters between those two
3841 (inclusive) in the collating sequence,
3842 e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
3843 any decimal digit. It is illegal for two ranges to share an
3844 endpoint, e.g., <literal>a-c-e</literal>. Ranges are very
3845 collating-sequence-dependent, so portable programs should avoid
3850 To include a literal <literal>]</literal> in the list, make it the
3851 first character (after <literal>^</literal>, if that is used). To
3852 include a literal <literal>-</literal>, make it the first or last
3853 character, or the second endpoint of a range. To use a literal
3854 <literal>-</literal> as the first endpoint of a range, enclose it
3855 in <literal>[.</literal> and <literal>.]</literal> to make it a
3856 collating element (see below). With the exception of these characters,
3857 some combinations using <literal>[</literal>
3858 (see next paragraphs), and escapes (AREs only), all other special
3859 characters lose their special significance within a bracket expression.
3860 In particular, <literal>\</literal> is not special when following
3861 ERE or BRE rules, though it is special (as introducing an escape)
3866 Within a bracket expression, a collating element (a character, a
3867 multiple-character sequence that collates as if it were a single
3868 character, or a collating-sequence name for either) enclosed in
3869 <literal>[.</literal> and <literal>.]</literal> stands for the
3870 sequence of characters of that collating element. The sequence is
3871 treated as a single element of the bracket expression's list. This
3873 expression containing a multiple-character collating element to
3874 match more than one character, e.g., if the collating sequence
3875 includes a <literal>ch</literal> collating element, then the RE
3876 <literal>[[.ch.]]*c</literal> matches the first five characters of
3877 <literal>chchcc</literal>.
3882 <productname>PostgreSQL</> currently does not support multi-character collating
3883 elements. This information describes possible future behavior.
3888 Within a bracket expression, a collating element enclosed in
3889 <literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
3890 class</>, standing for the sequences of characters of all collating
3891 elements equivalent to that one, including itself. (If there are
3892 no other equivalent collating elements, the treatment is as if the
3893 enclosing delimiters were <literal>[.</literal> and
3894 <literal>.]</literal>.) For example, if <literal>o</literal> and
3895 <literal>^</literal> are the members of an equivalence class, then
3896 <literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
3897 <literal>[o^]</literal> are all synonymous. An equivalence class
3898 cannot be an endpoint of a range.
3902 Within a bracket expression, the name of a character class
3903 enclosed in <literal>[:</literal> and <literal>:]</literal> stands
3904 for the list of all characters belonging to that class. Standard
3905 character class names are: <literal>alnum</literal>,
3906 <literal>alpha</literal>, <literal>blank</literal>,
3907 <literal>cntrl</literal>, <literal>digit</literal>,
3908 <literal>graph</literal>, <literal>lower</literal>,
3909 <literal>print</literal>, <literal>punct</literal>,
3910 <literal>space</literal>, <literal>upper</literal>,
3911 <literal>xdigit</literal>. These stand for the character classes
3913 <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
3914 A locale can provide others. A character class cannot be used as
3915 an endpoint of a range.
3919 There are two special cases of bracket expressions: the bracket
3920 expressions <literal>[[:<:]]</literal> and
3921 <literal>[[:>:]]</literal> are constraints,
3922 matching empty strings at the beginning
3923 and end of a word respectively. A word is defined as a sequence
3924 of word characters that is neither preceded nor followed by word
3925 characters. A word character is an <literal>alnum</> character (as
3927 <citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
3928 or an underscore. This is an extension, compatible with but not
3929 specified by <acronym>POSIX</acronym> 1003.2, and should be used with
3930 caution in software intended to be portable to other systems.
3931 The constraint escapes described below are usually preferable; they
3932 are no more standard, but are easier to type.
3936 <sect3 id="posix-escape-sequences
">
3937 <title>Regular Expression Escapes</title>
3940 <firstterm>Escapes</> are special sequences beginning with <literal>\</>
3941 followed by an alphanumeric character. Escapes come in several varieties:
3942 character entry, class shorthands, constraint escapes, and back references.
3943 A <literal>\</> followed by an alphanumeric character but not constituting
3944 a valid escape is illegal in AREs.
3945 In EREs, there are no escapes: outside a bracket expression,
3946 a <literal>\</> followed by an alphanumeric character merely stands for
3947 that character as an ordinary character, and inside a bracket expression,
3948 <literal>\</> is an ordinary character.
3949 (The latter is the one actual incompatibility between EREs and AREs.)
3953 <firstterm>Character-entry escapes</> exist to make it easier to specify
3954 non-printing and other inconvenient characters in REs. They are
3955 shown in <xref linkend="posix-character-entry-escapes-table
">.
3959 <firstterm>Class-shorthand escapes</> provide shorthands for certain
3960 commonly-used character classes. They are
3961 shown in <xref linkend="posix-class-shorthand-escapes-table
">.
3965 A <firstterm>constraint escape</> is a constraint,
3966 matching the empty string if specific conditions are met,
3967 written as an escape. They are
3968 shown in <xref linkend="posix-constraint-escapes-table
">.
3972 A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
3973 same string matched by the previous parenthesized subexpression specified
3974 by the number <replaceable>n</>
3975 (see <xref linkend="posix-constraint-backref-table
">). For example,
3976 <literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
3977 but not <literal>bc</> or <literal>cb</>.
3978 The subexpression must entirely precede the back reference in the RE.
3979 Subexpressions are numbered in the order of their leading parentheses.
3980 Non-capturing parentheses do not define subexpressions.
3985 Keep in mind that an escape's leading <literal>\</> will need to be
3986 doubled when entering the pattern as an SQL string constant. For example:
3988 '123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
3993 <table id="posix-character-entry-escapes-table
">
3994 <title>Regular Expression Character-Entry Escapes</title>
3999 <entry>Escape</entry>
4000 <entry>Description</entry>
4006 <entry> <literal>\a</> </entry>
4007 <entry> alert (bell) character, as in C </entry>
4011 <entry> <literal>\b</> </entry>
4012 <entry> backspace, as in C </entry>
4016 <entry> <literal>\B</> </entry>
4017 <entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
4022 <entry> <literal>\c</><replaceable>X</> </entry>
4023 <entry> (where <replaceable>X</> is any character) the character whose
4024 low-order 5 bits are the same as those of
4025 <replaceable>X</>, and whose other bits are all zero </entry>
4029 <entry> <literal>\e</> </entry>
4030 <entry> the character whose collating-sequence name
4032 or failing that, the character with octal value 033 </entry>
4036 <entry> <literal>\f</> </entry>
4037 <entry> form feed, as in C </entry>
4041 <entry> <literal>\n</> </entry>
4042 <entry> newline, as in C </entry>
4046 <entry> <literal>\r</> </entry>
4047 <entry> carriage return, as in C </entry>
4051 <entry> <literal>\t</> </entry>
4052 <entry> horizontal tab, as in C </entry>
4056 <entry> <literal>\u</><replaceable>wxyz</> </entry>
4057 <entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
4058 the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
4059 in the local byte ordering </entry>
4063 <entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
4064 <entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
4066 reserved for a hypothetical Unicode extension to 32 bits
4071 <entry> <literal>\v</> </entry>
4072 <entry> vertical tab, as in C </entry>
4076 <entry> <literal>\x</><replaceable>hhh</> </entry>
4077 <entry> (where <replaceable>hhh</> is any sequence of hexadecimal
4079 the character whose hexadecimal value is
4080 <literal>0x</><replaceable>hhh</>
4081 (a single character no matter how many hexadecimal digits are used)
4086 <entry> <literal>\0</> </entry>
4087 <entry> the character whose value is <literal>0</> (the null byte)</entry>
4091 <entry> <literal>\</><replaceable>xy</> </entry>
4092 <entry> (where <replaceable>xy</> is exactly two octal digits,
4093 and is not a <firstterm>back reference</>)
4094 the character whose octal value is
4095 <literal>0</><replaceable>xy</> </entry>
4099 <entry> <literal>\</><replaceable>xyz</> </entry>
4100 <entry> (where <replaceable>xyz</> is exactly three octal digits,
4101 and is not a <firstterm>back reference</>)
4102 the character whose octal value is
4103 <literal>0</><replaceable>xyz</> </entry>
4110 Hexadecimal digits are <literal>0</>-<literal>9</>,
4111 <literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
4112 Octal digits are <literal>0</>-<literal>7</>.
4116 The character-entry escapes are always taken as ordinary characters.
4117 For example, <literal>\135</> is <literal>]</> in ASCII, but
4118 <literal>\135</> does not terminate a bracket expression.
4121 <table id="posix-class-shorthand-escapes-table
">
4122 <title>Regular Expression Class-Shorthand Escapes</title>
4127 <entry>Escape</entry>
4128 <entry>Description</entry>
4134 <entry> <literal>\d</> </entry>
4135 <entry> <literal>[[:digit:]]</> </entry>
4139 <entry> <literal>\s</> </entry>
4140 <entry> <literal>[[:space:]]</> </entry>
4144 <entry> <literal>\w</> </entry>
4145 <entry> <literal>[[:alnum:]_]</>
4146 (note underscore is included) </entry>
4150 <entry> <literal>\D</> </entry>
4151 <entry> <literal>[^[:digit:]]</> </entry>
4155 <entry> <literal>\S</> </entry>
4156 <entry> <literal>[^[:space:]]</> </entry>
4160 <entry> <literal>\W</> </entry>
4161 <entry> <literal>[^[:alnum:]_]</>
4162 (note underscore is included) </entry>
4169 Within bracket expressions, <literal>\d</>, <literal>\s</>,
4170 and <literal>\w</> lose their outer brackets,
4171 and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
4172 (So, for example, <literal>[a-c\d]</> is equivalent to
4173 <literal>[a-c[:digit:]]</>.
4174 Also, <literal>[a-c\D]</>, which is equivalent to
4175 <literal>[a-c^[:digit:]]</>, is illegal.)
4178 <table id="posix-constraint-escapes-table
">
4179 <title>Regular Expression Constraint Escapes</title>
4184 <entry>Escape</entry>
4185 <entry>Description</entry>
4191 <entry> <literal>\A</> </entry>
4192 <entry> matches only at the beginning of the string
4193 (see <xref linkend="posix-matching-rules
"> for how this differs from
4194 <literal>^</>) </entry>
4198 <entry> <literal>\m</> </entry>
4199 <entry> matches only at the beginning of a word </entry>
4203 <entry> <literal>\M</> </entry>
4204 <entry> matches only at the end of a word </entry>
4208 <entry> <literal>\y</> </entry>
4209 <entry> matches only at the beginning or end of a word </entry>
4213 <entry> <literal>\Y</> </entry>
4214 <entry> matches only at a point that is not the beginning or end of a
4219 <entry> <literal>\Z</> </entry>
4220 <entry> matches only at the end of the string
4221 (see <xref linkend="posix-matching-rules
"> for how this differs from
4222 <literal>$</>) </entry>
4229 A word is defined as in the specification of
4230 <literal>[[:<:]]</> and <literal>[[:>:]]</> above.
4231 Constraint escapes are illegal within bracket expressions.
4234 <table id="posix-constraint-backref-table
">
4235 <title>Regular Expression Back References</title>
4240 <entry>Escape</entry>
4241 <entry>Description</entry>
4247 <entry> <literal>\</><replaceable>m</> </entry>
4248 <entry> (where <replaceable>m</> is a nonzero digit)
4249 a back reference to the <replaceable>m</>'th subexpression </entry>
4253 <entry> <literal>\</><replaceable>mnn</> </entry>
4254 <entry> (where <replaceable>m</> is a nonzero digit, and
4255 <replaceable>nn</> is some more digits, and the decimal value
4256 <replaceable>mnn</> is not greater than the number of closing capturing
4257 parentheses seen so far)
4258 a back reference to the <replaceable>mnn</>'th subexpression </entry>
4266 There is an inherent ambiguity between octal character-entry
4267 escapes and back references, which is resolved by the following heuristics,
4269 A leading zero always indicates an octal escape.
4270 A single non-zero digit, not followed by another digit,
4271 is always taken as a back reference.
4272 A multi-digit sequence not starting with a zero is taken as a back
4273 reference if it comes after a suitable subexpression
4274 (i.e., the number is in the legal range for a back reference),
4275 and otherwise is taken as octal.
4280 <sect3 id="posix-metasyntax
">
4281 <title>Regular Expression Metasyntax</title>
4284 In addition to the main syntax described above, there are some special
4285 forms and miscellaneous syntactic facilities available.
4289 Normally the flavor of RE being used is determined by
4290 <varname>regex_flavor</>.
4291 However, this can be overridden by a <firstterm>director</> prefix.
4292 If an RE begins with <literal>***:</>,
4293 the rest of the RE is taken as an ARE regardless of
4294 <varname>regex_flavor</>.
4295 If an RE begins with <literal>***=</>,
4296 the rest of the RE is taken to be a literal string,
4297 with all characters considered ordinary characters.
4301 An ARE can begin with <firstterm>embedded options</>:
4302 a sequence <literal>(?</><replaceable>xyz</><literal>)</>
4303 (where <replaceable>xyz</> is one or more alphabetic characters)
4304 specifies options affecting the rest of the RE.
4305 These options override any previously determined options (including
4306 both the RE flavor and case sensitivity).
4307 The available option letters are
4308 shown in <xref linkend="posix-embedded-options-table
">.
4311 <table id="posix-embedded-options-table
">
4312 <title>ARE Embedded-Option Letters</title>
4317 <entry>Option</entry>
4318 <entry>Description</entry>
4324 <entry> <literal>b</> </entry>
4325 <entry> rest of RE is a BRE </entry>
4329 <entry> <literal>c</> </entry>
4330 <entry> case-sensitive matching (overrides operator type) </entry>
4334 <entry> <literal>e</> </entry>
4335 <entry> rest of RE is an ERE </entry>
4339 <entry> <literal>i</> </entry>
4340 <entry> case-insensitive matching (see
4341 <xref linkend="posix-matching-rules
">) (overrides operator type) </entry>
4345 <entry> <literal>m</> </entry>
4346 <entry> historical synonym for <literal>n</> </entry>
4350 <entry> <literal>n</> </entry>
4351 <entry> newline-sensitive matching (see
4352 <xref linkend="posix-matching-rules
">) </entry>
4356 <entry> <literal>p</> </entry>
4357 <entry> partial newline-sensitive matching (see
4358 <xref linkend="posix-matching-rules
">) </entry>
4362 <entry> <literal>q</> </entry>
4363 <entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
4368 <entry> <literal>s</> </entry>
4369 <entry> non-newline-sensitive matching (default) </entry>
4373 <entry> <literal>t</> </entry>
4374 <entry> tight syntax (default; see below) </entry>
4378 <entry> <literal>w</> </entry>
4379 <entry> inverse partial newline-sensitive (<quote>weird</>) matching
4380 (see <xref linkend="posix-matching-rules
">) </entry>
4384 <entry> <literal>x</> </entry>
4385 <entry> expanded syntax (see below) </entry>
4392 Embedded options take effect at the <literal>)</> terminating the sequence.
4393 They can appear only at the start of an ARE (after the
4394 <literal>***:</> director if any).
4398 In addition to the usual (<firstterm>tight</>) RE syntax, in which all
4399 characters are significant, there is an <firstterm>expanded</> syntax,
4400 available by specifying the embedded <literal>x</> option.
4401 In the expanded syntax,
4402 white-space characters in the RE are ignored, as are
4403 all characters between a <literal>#</>
4404 and the following newline (or the end of the RE). This
4405 permits paragraphing and commenting a complex RE.
4406 There are three exceptions to that basic rule:
4411 a white-space character or <literal>#</> preceded by <literal>\</> is
4417 white space or <literal>#</> within a bracket expression is retained
4422 white space and comments cannot appear within multi-character symbols,
4423 such as <literal>(?:</>
4428 For this purpose, white-space characters are blank, tab, newline, and
4429 any character that belongs to the <replaceable>space</> character class.
4433 Finally, in an ARE, outside bracket expressions, the sequence
4434 <literal>(?#</><replaceable>ttt</><literal>)</>
4435 (where <replaceable>ttt</> is any text not containing a <literal>)</>)
4436 is a comment, completely ignored.
4437 Again, this is not allowed between the characters of
4438 multi-character symbols, like <literal>(?:</>.
4439 Such comments are more a historical artifact than a useful facility,
4440 and their use is deprecated; use the expanded syntax instead.
4444 <emphasis>None</> of these metasyntax extensions is available if
4445 an initial <literal>***=</> director
4446 has specified that the user's input be treated as a literal string
4447 rather than as an RE.
4451 <sect3 id="posix-matching-rules
">
4452 <title>Regular Expression Matching Rules</title>
4455 In the event that an RE could match more than one substring of a given
4456 string, the RE matches the one starting earliest in the string.
4457 If the RE could match more than one substring starting at that point,
4458 either the longest possible match or the shortest possible match will
4459 be taken, depending on whether the RE is <firstterm>greedy</> or
4460 <firstterm>non-greedy</>.
4464 Whether an RE is greedy or not is determined by the following rules:
4468 Most atoms, and all constraints, have no greediness attribute (because
4469 they cannot match variable amounts of text anyway).
4474 Adding parentheses around an RE does not change its greediness.
4479 A quantified atom with a fixed-repetition quantifier
4480 (<literal>{</><replaceable>m</><literal>}</>
4482 <literal>{</><replaceable>m</><literal>}?</>)
4483 has the same greediness (possibly none) as the atom itself.
4488 A quantified atom with other normal quantifiers (including
4489 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
4490 with <replaceable>m</> equal to <replaceable>n</>)
4491 is greedy (prefers longest match).
4496 A quantified atom with a non-greedy quantifier (including
4497 <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
4498 with <replaceable>m</> equal to <replaceable>n</>)
4499 is non-greedy (prefers shortest match).
4504 A branch — that is, an RE that has no top-level
4505 <literal>|</> operator — has the same greediness as the first
4506 quantified atom in it that has a greediness attribute.
4511 An RE consisting of two or more branches connected by the
4512 <literal>|</> operator is always greedy.
4519 The above rules associate greediness attributes not only with individual
4520 quantified atoms, but with branches and entire REs that contain quantified
4521 atoms. What that means is that the matching is done in such a way that
4522 the branch, or whole RE, matches the longest or shortest possible
4523 substring <emphasis>as a whole</>. Once the length of the entire match
4524 is determined, the part of it that matches any particular subexpression
4525 is determined on the basis of the greediness attribute of that
4526 subexpression, with subexpressions starting earlier in the RE taking
4527 priority over ones starting later.
4531 An example of what this means:
4533 SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
4534 <lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
4535 SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
4536 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
4538 In the first case, the RE as a whole is greedy because <literal>Y*</>
4539 is greedy. It can match beginning at the <literal>Y</>, and it matches
4540 the longest possible string starting there, i.e., <literal>Y123</>.
4541 The output is the parenthesized part of that, or <literal>123</>.
4542 In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
4543 is non-greedy. It can match beginning at the <literal>Y</>, and it matches
4544 the shortest possible string starting there, i.e., <literal>Y1</>.
4545 The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
4546 the decision as to the overall match length; so it is forced to match
4551 In short, when an RE contains both greedy and non-greedy subexpressions,
4552 the total match length is either as long as possible or as short as
4553 possible, according to the attribute assigned to the whole RE. The
4554 attributes assigned to the subexpressions only affect how much of that
4555 match they are allowed to <quote>eat</> relative to each other.
4559 The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
4560 can be used to force greediness or non-greediness, respectively,
4561 on a subexpression or a whole RE.
4565 Match lengths are measured in characters, not collating elements.
4566 An empty string is considered longer than no match at all.
4569 matches the three middle characters of <literal>abbbc</>;
4570 <literal>(week|wee)(night|knights)</>
4571 matches all ten characters of <literal>weeknights</>;
4572 when <literal>(.*).*</>
4573 is matched against <literal>abc</> the parenthesized subexpression
4574 matches all three characters; and when
4575 <literal>(a*)*</> is matched against <literal>bc</>
4576 both the whole RE and the parenthesized
4577 subexpression match an empty string.
4581 If case-independent matching is specified,
4582 the effect is much as if all case distinctions had vanished from the
4584 When an alphabetic that exists in multiple cases appears as an
4585 ordinary character outside a bracket expression, it is effectively
4586 transformed into a bracket expression containing both cases,
4587 e.g., <literal>x</> becomes <literal>[xX]</>.
4588 When it appears inside a bracket expression, all case counterparts
4589 of it are added to the bracket expression, e.g.,
4590 <literal>[x]</> becomes <literal>[xX]</>
4591 and <literal>[^x]</> becomes <literal>[^xX]</>.
4595 If newline-sensitive matching is specified, <literal>.</>
4596 and bracket expressions using <literal>^</>
4597 will never match the newline character
4598 (so that matches will never cross newlines unless the RE
4599 explicitly arranges it)
4600 and <literal>^</>and <literal>$</>
4601 will match the empty string after and before a newline
4602 respectively, in addition to matching at beginning and end of string
4604 But the ARE escapes <literal>\A</> and <literal>\Z</>
4605 continue to match beginning or end of string <emphasis>only</>.
4609 If partial newline-sensitive matching is specified,
4610 this affects <literal>.</> and bracket expressions
4611 as with newline-sensitive matching, but not <literal>^</>
4616 If inverse partial newline-sensitive matching is specified,
4617 this affects <literal>^</> and <literal>$</>
4618 as with newline-sensitive matching, but not <literal>.</>
4619 and bracket expressions.
4620 This isn't very useful but is provided for symmetry.
4624 <sect3 id="posix-limits-compatibility
">
4625 <title>Limits and Compatibility</title>
4628 No particular limit is imposed on the length of REs in this
4629 implementation. However,
4630 programs intended to be highly portable should not employ REs longer
4632 as a POSIX-compliant implementation can refuse to accept such REs.
4636 The only feature of AREs that is actually incompatible with
4637 POSIX EREs is that <literal>\</> does not lose its special
4638 significance inside bracket expressions.
4639 All other ARE features use syntax which is illegal or has
4640 undefined or unspecified effects in POSIX EREs;
4641 the <literal>***</> syntax of directors likewise is outside the POSIX
4642 syntax for both BREs and EREs.
4646 Many of the ARE extensions are borrowed from Perl, but some have
4647 been changed to clean them up, and a few Perl extensions are not present.
4648 Incompatibilities of note include <literal>\b</>, <literal>\B</>,
4649 the lack of special treatment for a trailing newline,
4650 the addition of complemented bracket expressions to the things
4651 affected by newline-sensitive matching,
4652 the restrictions on parentheses and back references in lookahead
4653 constraints, and the longest/shortest-match (rather than first-match)
4658 Two significant incompatibilities exist between AREs and the ERE syntax
4659 recognized by pre-7.4 releases of <productname>PostgreSQL</>:
4664 In AREs, <literal>\</> followed by an alphanumeric character is either
4665 an escape or an error, while in previous releases, it was just another
4666 way of writing the alphanumeric.
4667 This should not be much of a problem because there was no reason to
4668 write such a sequence in earlier releases.
4673 In AREs, <literal>\</> remains a special character within
4674 <literal>[]</>, so a literal <literal>\</> within a bracket
4675 expression must be written <literal>\\</>.
4680 While these differences are unlikely to create a problem for most
4681 applications, you can avoid them if necessary by
4682 setting <varname>regex_flavor</> to <literal>extended</>.
4686 <sect3 id="posix-basic-regexes
">
4687 <title>Basic Regular Expressions</title>
4690 BREs differ from EREs in several respects.
4691 In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
4692 are ordinary characters and there is no equivalent
4693 for their functionality.
4694 The delimiters for bounds are
4695 <literal>\{</> and <literal>\}</>,
4696 with <literal>{</> and <literal>}</>
4697 by themselves ordinary characters.
4698 The parentheses for nested subexpressions are
4699 <literal>\(</> and <literal>\)</>,
4700 with <literal>(</> and <literal>)</> by themselves ordinary characters.
4701 <literal>^</> is an ordinary character except at the beginning of the
4702 RE or the beginning of a parenthesized subexpression,
4703 <literal>$</> is an ordinary character except at the end of the
4704 RE or the end of a parenthesized subexpression,
4705 and <literal>*</> is an ordinary character if it appears at the beginning
4706 of the RE or the beginning of a parenthesized subexpression
4707 (after a possible leading <literal>^</>).
4708 Finally, single-digit back references are available, and
4709 <literal>\<</> and <literal>\></>
4711 <literal>[[:<:]]</> and <literal>[[:>:]]</>
4712 respectively; no other escapes are available in BREs.
4716 <!-- end re_syntax.n man page -->
4722 <sect1 id="functions-formatting
">
4723 <title>Data Type Formatting Functions</title>
4726 <primary>formatting</primary>
4730 <primary>to_char</primary>
4733 <primary>to_date</primary>
4736 <primary>to_number</primary>
4739 <primary>to_timestamp</primary>
4743 The <productname>PostgreSQL</productname> formatting functions
4744 provide a powerful set of tools for converting various data types
4745 (date/time, integer, floating point, numeric) to formatted strings
4746 and for converting from formatted strings to specific data types.
4747 <xref linkend="functions-formatting-table
"> lists them.
4748 These functions all follow a common calling convention: the first
4749 argument is the value to be formatted and the second argument is a
4750 template that defines the output or input format.
4753 A single-argument <function>to_timestamp</function> function is also
4754 available; it accepts a
4755 <type>double precision</type> argument and converts from Unix epoch
4756 (seconds since 1970-01-01 00:00:00+00) to
4757 <type>timestamp with time zone</type>.
4758 (<type>Integer</type> Unix epochs are implicitly cast to
4759 <type>double precision</type>.)
4762 <table id="functions-formatting-table
">
4763 <title>Formatting Functions</title>
4767 <entry>Function</entry>
4768 <entry>Return Type</entry>
4769 <entry>Description</entry>
4770 <entry>Example</entry>
4775 <entry><literal><function>to_char</function>(<type>timestamp</type>, <type>text</type>)</literal></entry>
4776 <entry><type>text</type></entry>
4777 <entry>convert time stamp to string</entry>
4778 <entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
4781 <entry><literal><function>to_char</function>(<type>interval</type>, <type>text</type>)</literal></entry>
4782 <entry><type>text</type></entry>
4783 <entry>convert interval to string</entry>
4784 <entry><literal>to_char(interval '15h 2m 12s', 'HH24:MI:SS')</literal></entry>
4787 <entry><literal><function>to_char</function>(<type>int</type>, <type>text</type>)</literal></entry>
4788 <entry><type>text</type></entry>
4789 <entry>convert integer to string</entry>
4790 <entry><literal>to_char(125, '999')</literal></entry>
4793 <entry><literal><function>to_char</function>(<type>double precision</type>,
4794 <type>text</type>)</literal></entry>
4795 <entry><type>text</type></entry>
4796 <entry>convert real/double precision to string</entry>
4797 <entry><literal>to_char(125.8::real, '999D9')</literal></entry>
4800 <entry><literal><function>to_char</function>(<type>numeric</type>, <type>text</type>)</literal></entry>
4801 <entry><type>text</type></entry>
4802 <entry>convert numeric to string</entry>
4803 <entry><literal>to_char(-125.8, '999D99S')</literal></entry>
4806 <entry><literal><function>to_date</function>(<type>text</type>, <type>text</type>)</literal></entry>
4807 <entry><type>date</type></entry>
4808 <entry>convert string to date</entry>
4809 <entry><literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal></entry>
4812 <entry><literal><function>to_number</function>(<type>text</type>, <type>text</type>)</literal></entry>
4813 <entry><type>numeric</type></entry>
4814 <entry>convert string to numeric</entry>
4815 <entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
4818 <entry><literal><function>to_timestamp</function>(<type>text</type>, <type>text</type>)</literal></entry>
4819 <entry><type>timestamp with time zone</type></entry>
4820 <entry>convert string to time stamp</entry>
4821 <entry><literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal></entry>
4824 <entry><literal><function>to_timestamp</function>(<type>double precision</type>)</literal></entry>
4825 <entry><type>timestamp with time zone</type></entry>
4826 <entry>convert Unix epoch to time stamp</entry>
4827 <entry><literal>to_timestamp(1284352323)</literal></entry>
4834 In a <function>to_char</> output template string, there are certain
4835 patterns that are recognized and replaced with appropriately-formatted
4836 data based on the given value. Any text that is not a template pattern is
4837 simply copied verbatim. Similarly, in an input template string (for the
4838 other functions), template patterns identify the values to be supplied by
4839 the input data string.
4843 <xref linkend="functions-formatting-datetime-table
"> shows the
4844 template patterns available for formatting date and time values.
4847 <table id="functions-formatting-datetime-table
">
4848 <title>Template Patterns for Date/Time Formatting</title>
4852 <entry>Pattern</entry>
4853 <entry>Description</entry>
4858 <entry><literal>HH</literal></entry>
4859 <entry>hour of day (01-12)</entry>
4862 <entry><literal>HH12</literal></entry>
4863 <entry>hour of day (01-12)</entry>
4866 <entry><literal>HH24</literal></entry>
4867 <entry>hour of day (00-23)</entry>
4870 <entry><literal>MI</literal></entry>
4871 <entry>minute (00-59)</entry>
4874 <entry><literal>SS</literal></entry>
4875 <entry>second (00-59)</entry>
4878 <entry><literal>MS</literal></entry>
4879 <entry>millisecond (000-999)</entry>
4882 <entry><literal>US</literal></entry>
4883 <entry>microsecond (000000-999999)</entry>
4886 <entry><literal>SSSS</literal></entry>
4887 <entry>seconds past midnight (0-86399)</entry>
4890 <entry><literal>AM</literal>, <literal>am</literal>,
4891 <literal>PM</literal> or <literal>pm</literal></entry>
4892 <entry>meridiem indicator (without periods)</entry>
4895 <entry><literal>A.M.</literal>, <literal>a.m.</literal>,
4896 <literal>P.M.</literal> or <literal>p.m.</literal></entry>
4897 <entry>meridiem indicator (with periods)</entry>
4900 <entry><literal>Y,YYY</literal></entry>
4901 <entry>year (4 and more digits) with comma</entry>
4904 <entry><literal>YYYY</literal></entry>
4905 <entry>year (4 and more digits)</entry>
4908 <entry><literal>YYY</literal></entry>
4909 <entry>last 3 digits of year</entry>
4912 <entry><literal>YY</literal></entry>
4913 <entry>last 2 digits of year</entry>
4916 <entry><literal>Y</literal></entry>
4917 <entry>last digit of year</entry>
4920 <entry><literal>IYYY</literal></entry>
4921 <entry>ISO year (4 and more digits)</entry>
4924 <entry><literal>IYY</literal></entry>
4925 <entry>last 3 digits of ISO year</entry>
4928 <entry><literal>IY</literal></entry>
4929 <entry>last 2 digits of ISO year</entry>
4932 <entry><literal>I</literal></entry>
4933 <entry>last digit of ISO year</entry>
4936 <entry><literal>BC</literal>, <literal>bc</literal>,
4937 <literal>AD</literal> or <literal>ad</literal></entry>
4938 <entry>era indicator (without periods)</entry>
4941 <entry><literal>B.C.</literal>, <literal>b.c.</literal>,
4942 <literal>A.D.</literal> or <literal>a.d.</literal></entry>
4943 <entry>era indicator (with periods)</entry>
4946 <entry><literal>MONTH</literal></entry>
4947 <entry>full uppercase month name (blank-padded to 9 chars)</entry>
4950 <entry><literal>Month</literal></entry>
4951 <entry>full capitalized month name (blank-padded to 9 chars)</entry>
4954 <entry><literal>month</literal></entry>
4955 <entry>full lowercase month name (blank-padded to 9 chars)</entry>
4958 <entry><literal>MON</literal></entry>
4959 <entry>abbreviated uppercase month name (3 chars in English, localized lengths vary)</entry>
4962 <entry><literal>Mon</literal></entry>
4963 <entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
4966 <entry><literal>mon</literal></entry>
4967 <entry>abbreviated lowercase month name (3 chars in English, localized lengths vary)</entry>
4970 <entry><literal>MM</literal></entry>
4971 <entry>month number (01-12)</entry>
4974 <entry><literal>DAY</literal></entry>
4975 <entry>full uppercase day name (blank-padded to 9 chars)</entry>
4978 <entry><literal>Day</literal></entry>
4979 <entry>full capitalized day name (blank-padded to 9 chars)</entry>
4982 <entry><literal>day</literal></entry>
4983 <entry>full lowercase day name (blank-padded to 9 chars)</entry>
4986 <entry><literal>DY</literal></entry>
4987 <entry>abbreviated uppercase day name (3 chars in English, localized lengths vary)</entry>
4990 <entry><literal>Dy</literal></entry>
4991 <entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
4994 <entry><literal>dy</literal></entry>
4995 <entry>abbreviated lowercase day name (3 chars in English, localized lengths vary)</entry>
4998 <entry><literal>DDD</literal></entry>
4999 <entry>day of year (001-366)</entry>
5002 <entry><literal>IDDD</literal></entry>
5003 <entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
5006 <entry><literal>DD</literal></entry>
5007 <entry>day of month (01-31)</entry>
5010 <entry><literal>D</literal></entry>
5011 <entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
5014 <entry><literal>ID</literal></entry>
5015 <entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
5018 <entry><literal>W</literal></entry>
5019 <entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
5022 <entry><literal>WW</literal></entry>
5023 <entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
5026 <entry><literal>IW</literal></entry>
5027 <entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
5030 <entry><literal>CC</literal></entry>
5031 <entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
5034 <entry><literal>J</literal></entry>
5035 <entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
5038 <entry><literal>Q</literal></entry>
5039 <entry>quarter</entry>
5042 <entry><literal>RM</literal></entry>
5043 <entry>month in uppercase Roman numerals (I-XII; I=January)</entry>
5046 <entry><literal>rm</literal></entry>
5047 <entry>month in lowercase Roman numerals (i-xii; i=January)</entry>
5050 <entry><literal>TZ</literal></entry>
5051 <entry>uppercase time-zone name</entry>
5054 <entry><literal>tz</literal></entry>
5055 <entry>lowercase time-zone name</entry>
5062 Modifiers can be applied to any template pattern to alter its
5063 behavior. For example, <literal>FMMonth</literal>
5064 is the <literal>Month</literal> pattern with the
5065 <literal>FM</literal> modifier.
5066 <xref linkend="functions-formatting-datetimemod-table
"> shows the
5067 modifier patterns for date/time formatting.
5070 <table id="functions-formatting-datetimemod-table
">
5071 <title>Template Pattern Modifiers for Date/Time Formatting</title>
5075 <entry>Modifier</entry>
5076 <entry>Description</entry>
5077 <entry>Example</entry>
5082 <entry><literal>FM</literal> prefix</entry>
5083 <entry>fill mode (suppress padding blanks and zeroes)</entry>
5084 <entry><literal>FMMonth</literal></entry>
5087 <entry><literal>TH</literal> suffix</entry>
5088 <entry>uppercase ordinal number suffix</entry>
5089 <entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
5092 <entry><literal>th</literal> suffix</entry>
5093 <entry>lowercase ordinal number suffix</entry>
5094 <entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
5097 <entry><literal>FX</literal> prefix</entry>
5098 <entry>fixed format global option (see usage notes)</entry>
5099 <entry><literal>FX Month DD Day</literal></entry>
5102 <entry><literal>TM</literal> prefix</entry>
5103 <entry>translation mode (print localized day and month names based on
5104 <xref linkend="guc-lc-time
">)</entry>
5105 <entry><literal>TMMonth</literal></entry>
5108 <entry><literal>SP</literal> suffix</entry>
5109 <entry>spell mode (not implemented)</entry>
5110 <entry><literal>DDSP</literal></entry>
5117 Usage notes for date/time formatting:
5122 <literal>FM</literal> suppresses leading zeroes and trailing blanks
5123 that would otherwise be added to make the output of a pattern be
5130 <literal>TM</literal> does not include trailing blanks.
5136 <function>to_timestamp</function> and <function>to_date</function>
5137 skip multiple blank spaces in the input string unless the
5138 <literal>FX</literal> option is used. For example,
5139 <literal>to_timestamp('2000 JUN', 'YYYY MON')</literal> works, but
5140 <literal>to_timestamp('2000 JUN', 'FXYYYY MON')</literal> returns an error
5141 because <function>to_timestamp</function> expects one space only.
5142 <literal>FX</literal> must be specified as the first item in
5149 Ordinary text is allowed in <function>to_char</function>
5150 templates and will be output literally. You can put a substring
5151 in double quotes to force it to be interpreted as literal text
5152 even if it contains pattern key words. For example, in
5153 <literal>'"Hello Year
"YYYY'</literal>, the <literal>YYYY</literal>
5154 will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
5161 If you want to have a double quote in the output you must
5162 precede it with a backslash, for example <literal>E'\\"YYYY
5163 Month\\
"'</literal>. <!-- "" font-lock sanity :-) -->
5164 (Two backslashes are necessary because the backslash
5165 has special meaning when using the escape string syntax.)
5171 The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
5172 <type>date</type> has a restriction when processing years with more than 4 digits. You must
5173 use some non-digit character or template after <literal>YYYY</literal>,
5174 otherwise the year is always interpreted as 4 digits. For example
5175 (with the year 20000):
5176 <literal>to_date('200001131', 'YYYYMMDD')</literal> will be
5177 interpreted as a 4-digit year; instead use a non-digit
5178 separator after the year, like
5179 <literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
5180 <literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
5186 In conversions from string to <type>timestamp</type> or
5187 <type>date</type>, the <literal>CC</literal> (century) field is ignored
5188 if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
5189 <literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
5190 <literal>YY</literal> or <literal>Y</literal> then the year is computed
5191 as <literal>(CC-1)*100+YY</literal>.
5197 An ISO week date (as distinct from a Gregorian date) can be
5198 specified to <function>to_timestamp</function> and
5199 <function>to_date</function> in one of two ways:
5203 Year, week, and weekday: for example <literal>to_date('2006-42-4',
5204 'IYYY-IW-ID')</literal> returns the date
5205 <literal>2006-10-19</literal>. If you omit the weekday it
5206 is assumed to be 1 (Monday).
5211 Year and day of year: for example <literal>to_date('2006-291',
5212 'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
5218 Attempting to construct a date using a mixture of ISO week and
5219 Gregorian date fields is nonsensical, and will cause an error. In the
5220 context of an ISO year, the concept of a <quote>month</> or <quote>day
5221 of month</> has no meaning. In the context of a Gregorian year, the
5222 ISO week has no meaning. Users should avoid mixing Gregorian and
5223 ISO date specifications.
5229 In a conversion from string to <type>timestamp</type>, millisecond
5230 (<literal>MS</literal>) or microsecond (<literal>US</literal>)
5231 values are used as the
5232 seconds digits after the decimal point. For example
5233 <literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
5234 but 300, because the conversion counts it as 12 + 0.3 seconds.
5235 This means for the format <literal>SS:MS</literal>, the input values
5236 <literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
5237 same number of milliseconds. To get three milliseconds, one must use
5238 <literal>12:003</literal>, which the conversion counts as
5239 12 + 0.003 = 12.003 seconds.
5245 <literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
5246 is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
5247 1230 microseconds = 2.021230 seconds.
5253 <function>to_char(..., 'ID')</function>'s day of the week numbering
5254 matches the <function>extract('isodow', ...)</function> function, but
5255 <function>to_char(..., 'D')</function>'s does not match
5256 <function>extract('dow', ...)</function>'s day numbering.
5262 <function>to_char(interval)</function> formats <literal>HH</> and
5263 <literal>HH12</> as hours in a single day, while <literal>HH24</>
5264 can output hours exceeding a single day, e.g., >24.
5272 <xref linkend="functions-formatting-numeric-table
"> shows the
5273 template patterns available for formatting numeric values.
5276 <table id="functions-formatting-numeric-table
">
5277 <title>Template Patterns for Numeric Formatting</title>
5281 <entry>Pattern</entry>
5282 <entry>Description</entry>
5287 <entry><literal>9</literal></entry>
5288 <entry>value with the specified number of digits</entry>
5291 <entry><literal>0</literal></entry>
5292 <entry>value with leading zeros</entry>
5295 <entry><literal>.</literal> (period)</entry>
5296 <entry>decimal point</entry>
5299 <entry><literal>,</literal> (comma)</entry>
5300 <entry>group (thousand) separator</entry>
5303 <entry><literal>PR</literal></entry>
5304 <entry>negative value in angle brackets</entry>
5307 <entry><literal>S</literal></entry>
5308 <entry>sign anchored to number (uses locale)</entry>
5311 <entry><literal>L</literal></entry>
5312 <entry>currency symbol (uses locale)</entry>
5315 <entry><literal>D</literal></entry>
5316 <entry>decimal point (uses locale)</entry>
5319 <entry><literal>G</literal></entry>
5320 <entry>group separator (uses locale)</entry>
5323 <entry><literal>MI</literal></entry>
5324 <entry>minus sign in specified position (if number < 0)</entry>
5327 <entry><literal>PL</literal></entry>
5328 <entry>plus sign in specified position (if number > 0)</entry>
5331 <entry><literal>SG</literal></entry>
5332 <entry>plus/minus sign in specified position</entry>
5335 <entry><literal>RN</literal></entry>
5336 <entry>Roman numeral (input between 1 and 3999)</entry>
5339 <entry><literal>TH</literal> or <literal>th</literal></entry>
5340 <entry>ordinal number suffix</entry>
5343 <entry><literal>V</literal></entry>
5344 <entry>shift specified number of digits (see notes)</entry>
5347 <entry><literal>EEEE</literal></entry>
5348 <entry>scientific notation (not implemented)</entry>
5355 Usage notes for numeric formatting:
5360 A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
5361 <literal>MI</literal> is not anchored to
5362 the number; for example,
5363 <literal>to_char(-12, 'MI9999')</literal> produces <literal>'- 12'</literal>
5364 but <literal>to_char(-12, 'S9999')</literal> produces <literal>' -12'</literal>.
5365 The Oracle implementation does not allow the use of
5366 <literal>MI</literal> before <literal>9</literal>, but rather
5367 requires that <literal>9</literal> precede
5368 <literal>MI</literal>.
5374 <literal>9</literal> results in a value with the same number of
5375 digits as there are <literal>9</literal>s. If a digit is
5376 not available it outputs a space.
5382 <literal>TH</literal> does not convert values less than zero
5383 and does not convert fractional numbers.
5389 <literal>PL</literal>, <literal>SG</literal>, and
5390 <literal>TH</literal> are <productname>PostgreSQL</productname>
5397 <literal>V</literal> effectively
5398 multiplies the input values by
5399 <literal>10^<replaceable>n</replaceable></literal>, where
5400 <replaceable>n</replaceable> is the number of digits following
5401 <literal>V</literal>.
5402 <function>to_char</function> does not support the use of
5403 <literal>V</literal> combined with a decimal point
5404 (e.g., <literal>99.9V99</literal> is not allowed).
5411 Certain modifiers can be applied to any template pattern to alter its
5412 behavior. For example, <literal>FM9999</literal>
5413 is the <literal>9999</literal> pattern with the
5414 <literal>FM</literal> modifier.
5415 <xref linkend="functions-formatting-numericmod-table
"> shows the
5416 modifier patterns for numeric formatting.
5419 <table id="functions-formatting-numericmod-table
">
5420 <title>Template Pattern Modifiers for Numeric Formatting</title>
5424 <entry>Modifier</entry>
5425 <entry>Description</entry>
5426 <entry>Example</entry>
5431 <entry><literal>FM</literal> prefix</entry>
5432 <entry>fill mode (suppress padding blanks and zeroes)</entry>
5433 <entry><literal>FM9999</literal></entry>
5436 <entry><literal>TH</literal> suffix</entry>
5437 <entry>uppercase ordinal number suffix</entry>
5438 <entry><literal>999TH</literal></entry>
5441 <entry><literal>th</literal> suffix</entry>
5442 <entry>lowercase ordinal number suffix</entry>
5443 <entry><literal>999th</literal></entry>
5450 <xref linkend="functions-formatting-examples-table
"> shows some
5451 examples of the use of the <function>to_char</function> function.
5454 <table id="functions-formatting-examples-table
">
5455 <title><function>to_char</function> Examples</title>
5459 <entry>Expression</entry>
5460 <entry>Result</entry>
5465 <entry><literal>to_char(current_timestamp, 'Day, DD HH12:MI:SS')</literal></entry>
5466 <entry><literal>'Tuesday , 06 05:39:18'</literal></entry>
5469 <entry><literal>to_char(current_timestamp, 'FMDay, FMDD HH12:MI:SS')</literal></entry>
5470 <entry><literal>'Tuesday, 6 05:39:18'</literal></entry>
5473 <entry><literal>to_char(-0.1, '99.99')</literal></entry>
5474 <entry><literal>' -.10'</literal></entry>
5477 <entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
5478 <entry><literal>'-.1'</literal></entry>
5481 <entry><literal>to_char(0.1, '0.9')</literal></entry>
5482 <entry><literal>' 0.1'</literal></entry>
5485 <entry><literal>to_char(12, '9990999.9')</literal></entry>
5486 <entry><literal>' 0012.0'</literal></entry>
5489 <entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
5490 <entry><literal>'0012.'</literal></entry>
5493 <entry><literal>to_char(485, '999')</literal></entry>
5494 <entry><literal>' 485'</literal></entry>
5497 <entry><literal>to_char(-485, '999')</literal></entry>
5498 <entry><literal>'-485'</literal></entry>
5501 <entry><literal>to_char(485, '9 9 9')</literal></entry>
5502 <entry><literal>' 4 8 5'</literal></entry>
5505 <entry><literal>to_char(1485, '9,999')</literal></entry>
5506 <entry><literal>' 1,485'</literal></entry>
5509 <entry><literal>to_char(1485, '9G999')</literal></entry>
5510 <entry><literal>' 1 485'</literal></entry>
5513 <entry><literal>to_char(148.5, '999.999')</literal></entry>
5514 <entry><literal>' 148.500'</literal></entry>
5517 <entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
5518 <entry><literal>'148.5'</literal></entry>
5521 <entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
5522 <entry><literal>'148.500'</literal></entry>
5525 <entry><literal>to_char(148.5, '999D999')</literal></entry>
5526 <entry><literal>' 148,500'</literal></entry>
5529 <entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
5530 <entry><literal>' 3 148,500'</literal></entry>
5533 <entry><literal>to_char(-485, '999S')</literal></entry>
5534 <entry><literal>'485-'</literal></entry>
5537 <entry><literal>to_char(-485, '999MI')</literal></entry>
5538 <entry><literal>'485-'</literal></entry>
5541 <entry><literal>to_char(485, '999MI')</literal></entry>
5542 <entry><literal>'485 '</literal></entry>
5545 <entry><literal>to_char(485, 'FM999MI')</literal></entry>
5546 <entry><literal>'485'</literal></entry>
5549 <entry><literal>to_char(485, 'PL999')</literal></entry>
5550 <entry><literal>'+485'</literal></entry>
5553 <entry><literal>to_char(485, 'SG999')</literal></entry>
5554 <entry><literal>'+485'</literal></entry>
5557 <entry><literal>to_char(-485, 'SG999')</literal></entry>
5558 <entry><literal>'-485'</literal></entry>
5561 <entry><literal>to_char(-485, '9SG99')</literal></entry>
5562 <entry><literal>'4-85'</literal></entry>
5565 <entry><literal>to_char(-485, '999PR')</literal></entry>
5566 <entry><literal>'<485>'</literal></entry>
5569 <entry><literal>to_char(485, 'L999')</literal></entry>
5570 <entry><literal>'DM 485</literal></entry>
5573 <entry><literal>to_char(485, 'RN')</literal></entry>
5574 <entry><literal>' CDLXXXV'</literal></entry>
5577 <entry><literal>to_char(485, 'FMRN')</literal></entry>
5578 <entry><literal>'CDLXXXV'</literal></entry>
5581 <entry><literal>to_char(5.2, 'FMRN')</literal></entry>
5582 <entry><literal>'V'</literal></entry>
5585 <entry><literal>to_char(482, '999th')</literal></entry>
5586 <entry><literal>' 482nd'</literal></entry>
5589 <entry><literal>to_char(485, '"Good
number:
"999')</literal></entry>
5590 <entry><literal>'Good number: 485'</literal></entry>
5593 <entry><literal>to_char(485.8, '"Pre:
"999" Post:
" .999')</literal></entry>
5594 <entry><literal>'Pre: 485 Post: .800'</literal></entry>
5597 <entry><literal>to_char(12, '99V999')</literal></entry>
5598 <entry><literal>' 12000'</literal></entry>
5601 <entry><literal>to_char(12.4, '99V999')</literal></entry>
5602 <entry><literal>' 12400'</literal></entry>
5605 <entry><literal>to_char(12.45, '99V9')</literal></entry>
5606 <entry><literal>' 125'</literal></entry>
5615 <sect1 id="functions-datetime
">
5616 <title>Date/Time Functions and Operators</title>
5619 <xref linkend="functions-datetime-table
"> shows the available
5620 functions for date/time value processing, with details appearing in
5621 the following subsections. <xref
5622 linkend="operators-datetime-table
"> illustrates the behaviors of
5623 the basic arithmetic operators (<literal>+</literal>,
5624 <literal>*</literal>, etc.). For formatting functions, refer to
5625 <xref linkend="functions-formatting
">. You should be familiar with
5626 the background information on date/time data types from <xref
5627 linkend="datatype-datetime
">.
5631 All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
5632 inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
5633 with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
5634 For brevity, these variants are not shown separately. Also, the
5635 <literal>+</> and <literal>*</> operators come in commutative pairs (for
5636 example both date + integer and integer + date); we show only one of each
5640 <table id="operators-datetime-table
">
5641 <title>Date/Time Operators</title>
5646 <entry>Operator</entry>
5647 <entry>Example</entry>
5648 <entry>Result</entry>
5654 <entry> <literal>+</literal> </entry>
5655 <entry><literal>date '2001-09-28' + integer '7'</literal></entry>
5656 <entry><literal>date '2001-10-05'</literal></entry>
5660 <entry> <literal>+</literal> </entry>
5661 <entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
5662 <entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
5666 <entry> <literal>+</literal> </entry>
5667 <entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
5668 <entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
5672 <entry> <literal>+</literal> </entry>
5673 <entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
5674 <entry><literal>interval '1 day 01:00:00'</literal></entry>
5678 <entry> <literal>+</literal> </entry>
5679 <entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
5680 <entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
5684 <entry> <literal>+</literal> </entry>
5685 <entry><literal>time '01:00' + interval '3 hours'</literal></entry>
5686 <entry><literal>time '04:00:00'</literal></entry>
5690 <entry> <literal>-</literal> </entry>
5691 <entry><literal>- interval '23 hours'</literal></entry>
5692 <entry><literal>interval '-23:00:00'</literal></entry>
5696 <entry> <literal>-</literal> </entry>
5697 <entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
5698 <entry><literal>integer '3'</literal> (days)</entry>
5702 <entry> <literal>-</literal> </entry>
5703 <entry><literal>date '2001-10-01' - integer '7'</literal></entry>
5704 <entry><literal>date '2001-09-24'</literal></entry>
5708 <entry> <literal>-</literal> </entry>
5709 <entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
5710 <entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
5714 <entry> <literal>-</literal> </entry>
5715 <entry><literal>time '05:00' - time '03:00'</literal></entry>
5716 <entry><literal>interval '02:00:00'</literal></entry>
5720 <entry> <literal>-</literal> </entry>
5721 <entry><literal>time '05:00' - interval '2 hours'</literal></entry>
5722 <entry><literal>time '03:00:00'</literal></entry>
5726 <entry> <literal>-</literal> </entry>
5727 <entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
5728 <entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
5732 <entry> <literal>-</literal> </entry>
5733 <entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
5734 <entry><literal>interval '1 day -01:00:00'</literal></entry>
5738 <entry> <literal>-</literal> </entry>
5739 <entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
5740 <entry><literal>interval '1 day 15:00:00'</literal></entry>
5744 <entry> <literal>*</literal> </entry>
5745 <entry><literal>900 * interval '1 second'</literal></entry>
5746 <entry><literal>interval '00:15:00'</literal></entry>
5750 <entry> <literal>*</literal> </entry>
5751 <entry><literal>21 * interval '1 day'</literal></entry>
5752 <entry><literal>interval '21 days'</literal></entry>
5756 <entry> <literal>*</literal> </entry>
5757 <entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
5758 <entry><literal>interval '03:30:00'</literal></entry>
5762 <entry> <literal>/</literal> </entry>
5763 <entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
5764 <entry><literal>interval '00:40:00'</literal></entry>
5771 <primary>age</primary>
5774 <primary>clock_timestamp</primary>
5777 <primary>current_date</primary>
5780 <primary>current_time</primary>
5783 <primary>current_timestamp</primary>
5786 <primary>date_part</primary>
5789 <primary>date_trunc</primary>
5792 <primary>extract</primary>
5795 <primary>isfinite</primary>
5798 <primary>justify_days</primary>
5801 <primary>justify_hours</primary>
5804 <primary>justify_interval</primary>
5807 <primary>localtime</primary>
5810 <primary>localtimestamp</primary>
5813 <primary>now</primary>
5816 <primary>statement_timestamp</primary>
5819 <primary>timeofday</primary>
5822 <primary>transaction_timestamp</primary>
5825 <table id="functions-datetime-table
">
5826 <title>Date/Time Functions</title>
5830 <entry>Function</entry>
5831 <entry>Return Type</entry>
5832 <entry>Description</entry>
5833 <entry>Example</entry>
5834 <entry>Result</entry>
5840 <entry><literal><function>age</function>(<type>timestamp</type>, <type>timestamp</type>)</literal></entry>
5841 <entry><type>interval</type></entry>
5842 <entry>Subtract arguments, producing a <quote>symbolic</> result that
5843 uses years and months</entry>
5844 <entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
5845 <entry><literal>43 years 9 mons 27 days</literal></entry>
5849 <entry><literal><function>age</function>(<type>timestamp</type>)</literal></entry>
5850 <entry><type>interval</type></entry>
5851 <entry>Subtract from <function>current_date</function> (at midnight)</entry>
5852 <entry><literal>age(timestamp '1957-06-13')</literal></entry>
5853 <entry><literal>43 years 8 mons 3 days</literal></entry>
5857 <entry><literal><function>clock_timestamp</function>()</literal></entry>
5858 <entry><type>timestamp with time zone</type></entry>
5859 <entry>Current date and time (changes during statement execution);
5860 see <xref linkend="functions-datetime-current
">
5867 <entry><literal><function>current_date</function></literal></entry>
5868 <entry><type>date</type></entry>
5869 <entry>Current date;
5870 see <xref linkend="functions-datetime-current
">
5877 <entry><literal><function>current_time</function></literal></entry>
5878 <entry><type>time with time zone</type></entry>
5879 <entry>Current time of day;
5880 see <xref linkend="functions-datetime-current
">
5887 <entry><literal><function>current_timestamp</function></literal></entry>
5888 <entry><type>timestamp with time zone</type></entry>
5889 <entry>Current date and time (start of current transaction);
5890 see <xref linkend="functions-datetime-current
">
5897 <entry><literal><function>date_part</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5898 <entry><type>double precision</type></entry>
5899 <entry>Get subfield (equivalent to <function>extract</function>);
5900 see <xref linkend="functions-datetime-extract
">
5902 <entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5903 <entry><literal>20</literal></entry>
5907 <entry><literal><function>date_part</function>(<type>text</type>, <type>interval</type>)</literal></entry>
5908 <entry><type>double precision</type></entry>
5909 <entry>Get subfield (equivalent to
5910 <function>extract</function>); see <xref linkend="functions-datetime-extract
">
5912 <entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
5913 <entry><literal>3</literal></entry>
5917 <entry><literal><function>date_trunc</function>(<type>text</type>, <type>timestamp</type>)</literal></entry>
5918 <entry><type>timestamp</type></entry>
5919 <entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc
">
5921 <entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
5922 <entry><literal>2001-02-16 20:00:00</literal></entry>
5926 <entry><literal><function>extract</function>(<parameter>field</parameter> from
5927 <type>timestamp</type>)</literal></entry>
5928 <entry><type>double precision</type></entry>
5929 <entry>Get subfield; see <xref linkend="functions-datetime-extract
">
5931 <entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
5932 <entry><literal>20</literal></entry>
5936 <entry><literal><function>extract</function>(<parameter>field</parameter> from
5937 <type>interval</type>)</literal></entry>
5938 <entry><type>double precision</type></entry>
5939 <entry>Get subfield; see <xref linkend="functions-datetime-extract
">
5941 <entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
5942 <entry><literal>3</literal></entry>
5946 <entry><literal><function>isfinite</function>(<type>date</type>)</literal></entry>
5947 <entry><type>boolean</type></entry>
5948 <entry>Test for finite date (not +/-infinity)</entry>
5949 <entry><literal>isfinite(date '2001-02-16')</literal></entry>
5950 <entry><literal>true</literal></entry>
5954 <entry><literal><function>isfinite</function>(<type>timestamp</type>)</literal></entry>
5955 <entry><type>boolean</type></entry>
5956 <entry>Test for finite time stamp (not +/-infinity)</entry>
5957 <entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
5958 <entry><literal>true</literal></entry>
5962 <entry><literal><function>isfinite</function>(<type>interval</type>)</literal></entry>
5963 <entry><type>boolean</type></entry>
5964 <entry>Test for finite interval</entry>
5965 <entry><literal>isfinite(interval '4 hours')</literal></entry>
5966 <entry><literal>true</literal></entry>
5970 <entry><literal><function>justify_days</function>(<type>interval</type>)</literal></entry>
5971 <entry><type>interval</type></entry>
5972 <entry>Adjust interval so 30-day time periods are represented as months</entry>
5973 <entry><literal>justify_days(interval '35 days')</literal></entry>
5974 <entry><literal>1 mon 5 days</literal></entry>
5978 <entry><literal><function>justify_hours</function>(<type>interval</type>)</literal></entry>
5979 <entry><type>interval</type></entry>
5980 <entry>Adjust interval so 24-hour time periods are represented as days</entry>
5981 <entry><literal>justify_hours(interval '27 hours')</literal></entry>
5982 <entry><literal>1 day 03:00:00</literal></entry>
5986 <entry><literal><function>justify_interval</function>(<type>interval</type>)</literal></entry>
5987 <entry><type>interval</type></entry>
5988 <entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
5989 <entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
5990 <entry><literal>29 days 23:00:00</literal></entry>
5994 <entry><literal><function>localtime</function></literal></entry>
5995 <entry><type>time</type></entry>
5996 <entry>Current time of day;
5997 see <xref linkend="functions-datetime-current
">
6004 <entry><literal><function>localtimestamp</function></literal></entry>
6005 <entry><type>timestamp</type></entry>
6006 <entry>Current date and time (start of current transaction);
6007 see <xref linkend="functions-datetime-current
">
6014 <entry><literal><function>now</function>()</literal></entry>
6015 <entry><type>timestamp with time zone</type></entry>
6016 <entry>Current date and time (start of current transaction);
6017 see <xref linkend="functions-datetime-current
">
6024 <entry><literal><function>statement_timestamp</function>()</literal></entry>
6025 <entry><type>timestamp with time zone</type></entry>
6026 <entry>Current date and time (start of current statement);
6027 see <xref linkend="functions-datetime-current
">
6034 <entry><literal><function>timeofday</function>()</literal></entry>
6035 <entry><type>text</type></entry>
6036 <entry>Current date and time
6037 (like <function>clock_timestamp</>, but as a <type>text</> string);
6038 see <xref linkend="functions-datetime-current
">
6045 <entry><literal><function>transaction_timestamp</function>()</literal></entry>
6046 <entry><type>timestamp with time zone</type></entry>
6047 <entry>Current date and time (start of current transaction);
6048 see <xref linkend="functions-datetime-current
">
6058 In addition to these functions, the SQL <literal>OVERLAPS</> operator is
6061 (<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
6062 (<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
6064 This expression yields true when two time periods (defined by their
6065 endpoints) overlap, false when they do not overlap. The endpoints
6066 can be specified as pairs of dates, times, or time stamps; or as
6067 a date, time, or time stamp followed by an interval.
6071 SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
6072 (DATE '2001-10-30', DATE '2002-10-30');
6073 <lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
6074 SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
6075 (DATE '2001-10-30', DATE '2002-10-30');
6076 <lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
6080 When adding an <type>interval</type> value to (or subtracting an
6081 <type>interval</type> value from) a <type>timestamp with time zone</type>
6082 value, the days component advances (or decrements) the date of the
6083 <type>timestamp with time zone</type> by the indicated number of days.
6084 Across daylight saving time changes (with the session time zone set to a
6085 time zone that recognizes DST), this means <literal>interval '1 day'</literal>
6086 does not necessarily equal <literal>interval '24 hours'</literal>.
6087 For example, with the session time zone set to <literal>CST7CDT</literal>,
6088 <literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
6089 will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
6090 while adding <literal>interval '24 hours'</literal> to the same initial
6091 <type>timestamp with time zone</type> produces
6092 <literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
6093 a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
6094 <literal>CST7CDT</literal>.
6098 Note there can be ambiguity in the <literal>months</> returned by
6099 <function>age</> because different months have a different number of
6100 days. <productname>PostgreSQL</>'s approach uses the month from the
6101 earlier of the two dates when calculating partial months. For example,
6102 <literal>age('2004-06-01', '2004-04-30')</> uses April to yield
6103 <literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
6104 days</> because May has 31 days, while April has only 30.
6107 <sect2 id="functions-datetime-extract
">
6108 <title><function>EXTRACT</function>, <function>date_part</function></title>
6111 <primary>date_part</primary>
6114 <primary>extract</primary>
6118 EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
6122 The <function>extract</function> function retrieves subfields
6123 such as year or hour from date/time values.
6124 <replaceable>source</replaceable> must be a value expression of
6125 type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
6126 (Expressions of type <type>date</type> are
6127 cast to <type>timestamp</type> and can therefore be used as
6128 well.) <replaceable>field</replaceable> is an identifier or
6129 string that selects what field to extract from the source value.
6130 The <function>extract</function> function returns values of type
6131 <type>double precision</type>.
6132 The following are valid field names:
6134 <!-- alphabetical -->
6137 <term><literal>century</literal></term>
6144 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
6145 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6146 SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
6147 <lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
6151 The first century starts at 0001-01-01 00:00:00 AD, although
6152 they did not know it at the time. This definition applies to all
6153 Gregorian calendar countries. There is no century number 0,
6154 you go from -1 century to 1 century.
6156 If you disagree with this, please write your complaint to:
6157 Pope, Cathedral Saint-Peter of Roma, Vatican.
6161 <productname>PostgreSQL</productname> releases before 8.0 did not
6162 follow the conventional numbering of centuries, but just returned
6163 the year field divided by 100.
6169 <term><literal>day</literal></term>
6172 The day (of the month) field (1 - 31)
6176 SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
6177 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6183 <term><literal>decade</literal></term>
6186 The year field divided by 10
6190 SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
6191 <lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
6197 <term><literal>dow</literal></term>
6200 The day of the week as Sunday(<literal>0</>) to
6201 Saturday(<literal>6</>)
6205 SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
6206 <lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
6209 Note that <function>extract</function>'s day of the week numbering
6210 differs from that of the <function>to_char(...,
6211 'D')</function> function.
6218 <term><literal>doy</literal></term>
6221 The day of the year (1 - 365/366)
6225 SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
6226 <lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
6232 <term><literal>epoch</literal></term>
6235 For <type>date</type> and <type>timestamp</type> values, the
6236 number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
6237 for <type>interval</type> values, the total number
6238 of seconds in the interval
6242 SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-08');
6243 <lineannotation>Result: </lineannotation><computeroutput>982384720</computeroutput>
6245 SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
6246 <lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
6250 Here is how you can convert an epoch value back to a time
6255 SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720 * INTERVAL '1 second';
6261 <term><literal>hour</literal></term>
6264 The hour field (0 - 23)
6268 SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
6269 <lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
6275 <term><literal>isodow</literal></term>
6278 The day of the week as Monday(<literal>1</>) to
6279 Sunday(<literal>7</>)
6283 SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
6284 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6287 This is identical to <literal>dow</> except for Sunday. This
6288 matches the <acronym>ISO</> 8601 day of the week numbering.
6295 <term><literal>isoyear</literal></term>
6298 The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
6302 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
6303 <lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
6304 SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
6305 <lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
6309 Each <acronym>ISO</acronym> year begins with the Monday of the week containing the 4th of January, so in early January or late December the <acronym>ISO</acronym> year may be different from the Gregorian year. See the <literal>week</literal> field for more information.
6312 This field is not available in PostgreSQL releases prior to 8.3.
6318 <term><literal>microseconds</literal></term>
6321 The seconds field, including fractional parts, multiplied by 1
6322 000 000; note that this includes full seconds
6326 SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
6327 <lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
6333 <term><literal>millennium</literal></term>
6340 SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
6341 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6345 Years in the 1900s are in the second millennium.
6346 The third millennium started January 1, 2001.
6350 <productname>PostgreSQL</productname> releases before 8.0 did not
6351 follow the conventional numbering of millennia, but just returned
6352 the year field divided by 1000.
6358 <term><literal>milliseconds</literal></term>
6361 The seconds field, including fractional parts, multiplied by
6362 1000. Note that this includes full seconds.
6366 SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
6367 <lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
6373 <term><literal>minute</literal></term>
6376 The minutes field (0 - 59)
6380 SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
6381 <lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
6387 <term><literal>month</literal></term>
6390 For <type>timestamp</type> values, the number of the month
6391 within the year (1 - 12) ; for <type>interval</type> values
6392 the number of months, modulo 12 (0 - 11)
6396 SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
6397 <lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
6399 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
6400 <lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
6402 SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
6403 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6409 <term><literal>quarter</literal></term>
6412 The quarter of the year (1 - 4) that the date is in
6416 SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
6417 <lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
6423 <term><literal>second</literal></term>
6426 The seconds field, including fractional parts (0 -
6427 59<footnote><simpara>60 if leap seconds are
6428 implemented by the operating system</simpara></footnote>)
6432 SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
6433 <lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
6435 SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
6436 <lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
6441 <term><literal>timezone</literal></term>
6444 The time zone offset from UTC, measured in seconds. Positive values
6445 correspond to time zones east of UTC, negative values to
6452 <term><literal>timezone_hour</literal></term>
6455 The hour component of the time zone offset
6461 <term><literal>timezone_minute</literal></term>
6464 The minute component of the time zone offset
6470 <term><literal>week</literal></term>
6473 The number of the week of the year that the day is in. By definition
6474 (<acronym>ISO</acronym> 8601), the first week of a year
6475 contains January 4 of that year. (The <acronym>ISO</acronym>-8601
6476 week starts on Monday.) In other words, the first Thursday of
6477 a year is in week 1 of that year.
6480 Because of this, it is possible for early January dates to be part of the
6481 52nd or 53rd week of the previous year. For example, <literal>2005-01-01</>
6482 is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of
6483 the 52nd week of year 2005.
6487 SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
6488 <lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
6494 <term><literal>year</literal></term>
6497 The year field. Keep in mind there is no <literal>0 AD</>, so subtracting
6498 <literal>BC</> years from <literal>AD</> years should be done with care.
6502 SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
6503 <lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
6512 The <function>extract</function> function is primarily intended
6513 for computational processing. For formatting date/time values for
6514 display, see <xref linkend="functions-formatting
">.
6518 The <function>date_part</function> function is modeled on the traditional
6519 <productname>Ingres</productname> equivalent to the
6520 <acronym>SQL</acronym>-standard function <function>extract</function>:
6522 date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6524 Note that here the <replaceable>field</replaceable> parameter needs to
6525 be a string value, not a name. The valid field names for
6526 <function>date_part</function> are the same as for
6527 <function>extract</function>.
6531 SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
6532 <lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
6534 SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
6535 <lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
6540 <sect2 id="functions-datetime-trunc
">
6541 <title><function>date_trunc</function></title>
6544 <primary>date_trunc</primary>
6548 The function <function>date_trunc</function> is conceptually
6549 similar to the <function>trunc</function> function for numbers.
6554 date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
6556 <replaceable>source</replaceable> is a value expression of type
6557 <type>timestamp</type> or <type>interval</>.
6558 (Values of type <type>date</type> and
6559 <type>time</type> are cast automatically to <type>timestamp</type> or
6560 <type>interval</>, respectively.)
6561 <replaceable>field</replaceable> selects to which precision to
6562 truncate the input value. The return value is of type
6563 <type>timestamp</type> or <type>interval</>
6564 with all fields that are less significant than the
6565 selected one set to zero (or one, for day and month).
6569 Valid values for <replaceable>field</replaceable> are:
6571 <member><literal>microseconds</literal></member>
6572 <member><literal>milliseconds</literal></member>
6573 <member><literal>second</literal></member>
6574 <member><literal>minute</literal></member>
6575 <member><literal>hour</literal></member>
6576 <member><literal>day</literal></member>
6577 <member><literal>week</literal></member>
6578 <member><literal>month</literal></member>
6579 <member><literal>quarter</literal></member>
6580 <member><literal>year</literal></member>
6581 <member><literal>decade</literal></member>
6582 <member><literal>century</literal></member>
6583 <member><literal>millennium</literal></member>
6590 SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
6591 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
6593 SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
6594 <lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
6599 <sect2 id="functions-datetime-zoneconvert
">
6600 <title><literal>AT TIME ZONE</literal></title>
6603 <primary>time zone</primary>
6604 <secondary>conversion</secondary>
6608 <primary>AT TIME ZONE</primary>
6612 The <literal>AT TIME ZONE</literal> construct allows conversions
6613 of time stamps to different time zones. <xref
6614 linkend="functions-datetime-zoneconvert-table
"> shows its
6618 <table id="functions-datetime-zoneconvert-table
">
6619 <title><literal>AT TIME ZONE</literal> Variants</title>
6623 <entry>Expression</entry>
6624 <entry>Return Type</entry>
6625 <entry>Description</entry>
6632 <literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6634 <entry><type>timestamp with time zone</type></entry>
6635 <entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
6640 <literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6642 <entry><type>timestamp without time zone</type></entry>
6643 <entry>Convert given time stamp <emphasis>with time zone</> to the new time
6644 zone, with no time zone designation</entry>
6649 <literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
6651 <entry><type>time with time zone</type></entry>
6652 <entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
6659 In these expressions, the desired time zone <replaceable>zone</> can be
6660 specified either as a text string (e.g., <literal>'PST'</literal>)
6661 or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
6662 In the text case, a time zone name can be specified in any of the ways
6663 described in <xref linkend="datatype-timezones
">.
6667 Examples (assuming the local time zone is <literal>PST8PDT</>):
6669 SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
6670 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
6672 SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
6673 <lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
6675 The first example takes a time stamp without time zone and interprets it as MST time
6676 (UTC-7), which is then converted to PST (UTC-8) for display. The second example takes
6677 a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
6681 The function <literal><function>timezone</function>(<replaceable>zone</>,
6682 <replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
6683 <literal><replaceable>timestamp</> AT TIME ZONE
6684 <replaceable>zone</></literal>.
6688 <sect2 id="functions-datetime-current
">
6689 <title>Current Date/Time</title>
6692 <primary>date</primary>
6693 <secondary>current</secondary>
6697 <primary>time</primary>
6698 <secondary>current</secondary>
6702 <productname>PostgreSQL</productname> provides a number of functions
6703 that return values related to the current date and time. These
6704 SQL-standard functions all return values based on the start time of
6705 the current transaction:
6710 CURRENT_TIME(<replaceable>precision</replaceable>)
6711 CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
6714 LOCALTIME(<replaceable>precision</replaceable>)
6715 LOCALTIMESTAMP(<replaceable>precision</replaceable>)
6720 <function>CURRENT_TIME</function> and
6721 <function>CURRENT_TIMESTAMP</function> deliver values with time zone;
6722 <function>LOCALTIME</function> and
6723 <function>LOCALTIMESTAMP</function> deliver values without time zone.
6727 <function>CURRENT_TIME</function>,
6728 <function>CURRENT_TIMESTAMP</function>,
6729 <function>LOCALTIME</function>, and
6730 <function>LOCALTIMESTAMP</function>
6732 a precision parameter, which causes the result to be rounded
6733 to that many fractional digits in the seconds field. Without a precision parameter,
6734 the result is given to the full available precision.
6740 SELECT CURRENT_TIME;
6741 <lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
6743 SELECT CURRENT_DATE;
6744 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
6746 SELECT CURRENT_TIMESTAMP;
6747 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
6749 SELECT CURRENT_TIMESTAMP(2);
6750 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
6752 SELECT LOCALTIMESTAMP;
6753 <lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
6758 Since these functions return
6759 the start time of the current transaction, their values do not
6760 change during the transaction. This is considered a feature:
6761 the intent is to allow a single transaction to have a consistent
6762 notion of the <quote>current</quote> time, so that multiple
6763 modifications within the same transaction bear the same
6769 Other database systems might advance these values more
6775 <productname>PostgreSQL</productname> also provides functions that
6776 return the start time of the current statement, as well as the actual
6777 current time at the instant the function is called. The complete list
6778 of non-SQL-standard time functions is:
6780 transaction_timestamp()
6781 statement_timestamp()
6789 <function>transaction_timestamp()</> is equivalent to
6790 <function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
6792 <function>statement_timestamp()</> returns the start time of the current
6793 statement (more specifically, the time of receipt of the latest command
6794 message from the client).
6795 <function>statement_timestamp()</> and <function>transaction_timestamp()</>
6796 return the same value during the first command of a transaction, but might
6797 differ during subsequent commands.
6798 <function>clock_timestamp()</> returns the actual current time, and
6799 therefore its value changes even within a single SQL command.
6800 <function>timeofday()</> is a historical
6801 <productname>PostgreSQL</productname> function. Like
6802 <function>clock_timestamp()</>, it returns the actual current time,
6803 but as a formatted <type>text</> string rather than a <type>timestamp
6804 with time zone</> value.
6805 <function>now()</> is a traditional <productname>PostgreSQL</productname>
6806 equivalent to <function>transaction_timestamp()</function>.
6810 All the date/time data types also accept the special literal value
6811 <literal>now</literal> to specify the current date and time (again,
6812 interpreted as the transaction start time). Thus,
6813 the following three all return the same result:
6815 SELECT CURRENT_TIMESTAMP;
6817 SELECT TIMESTAMP 'now'; -- incorrect for use with DEFAULT
6823 You do not want to use the third form when specifying a <literal>DEFAULT</>
6824 clause while creating a table. The system will convert <literal>now</literal>
6825 to a <type>timestamp</type> as soon as the constant is parsed, so that when
6826 the default value is needed,
6827 the time of the table creation would be used! The first two
6828 forms will not be evaluated until the default value is used,
6829 because they are function calls. Thus they will give the desired
6830 behavior of defaulting to the time of row insertion.
6835 <sect2 id="functions-datetime-delay
">
6836 <title>Delaying Execution</title>
6839 <primary>pg_sleep</primary>
6842 <primary>sleep</primary>
6845 <primary>delay</primary>
6849 The following function is available to delay execution of the server
6852 pg_sleep(<replaceable>seconds</replaceable>)
6855 <function>pg_sleep</function> makes the current session's process
6856 sleep until <replaceable>seconds</replaceable> seconds have
6857 elapsed. <replaceable>seconds</replaceable> is a value of type
6858 <type>double precision</>, so fractional-second delays can be specified.
6862 SELECT pg_sleep(1.5);
6868 The effective resolution of the sleep interval is platform-specific;
6869 0.01 seconds is a common value. The sleep delay will be at least as long
6870 as specified. It might be longer depending on factors such as server load.
6876 Make sure that your session does not hold more locks than necessary
6877 when calling <function>pg_sleep</function>. Otherwise other sessions
6878 might have to wait for your sleeping process, slowing down the entire
6887 <sect1 id="functions-enum
">
6888 <title>Enum Support Functions</title>
6891 For enum types (described in <xref linkend="datatype-enum
">),
6892 there are several functions that allow cleaner programming without
6893 hard-coding particular values of an enum type.
6894 These are listed in <xref linkend="functions-enum-table
">. The examples
6895 assume an enum type created as:
6898 CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
6903 <table id="functions-enum-table
">
6904 <title>Enum Support Functions</title>
6908 <entry>Function</entry>
6909 <entry>Description</entry>
6910 <entry>Example</entry>
6911 <entry>Example Result</entry>
6916 <entry><literal>enum_first(anyenum)</literal></entry>
6917 <entry>Returns the first value of the input enum type</entry>
6918 <entry><literal>enum_first(null::rainbow)</literal></entry>
6919 <entry><literal>red</literal></entry>
6922 <entry><literal>enum_last(anyenum)</literal></entry>
6923 <entry>Returns the last value of the input enum type</entry>
6924 <entry><literal>enum_last(null::rainbow)</literal></entry>
6925 <entry><literal>purple</literal></entry>
6928 <entry><literal>enum_range(anyenum)</literal></entry>
6929 <entry>Returns all values of the input enum type in an ordered array</entry>
6930 <entry><literal>enum_range(null::rainbow)</literal></entry>
6931 <entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
6934 <entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
6935 <entry morerows="2">
6936 Returns the range between the two given enum values, as an ordered
6937 array. The values must be from the same enum type. If the first
6938 parameter is null, the result will start with the first value of
6940 If the second parameter is null, the result will end with the last
6941 value of the enum type.
6943 <entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
6944 <entry><literal>{orange,yellow,green}</literal></entry>
6947 <entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
6948 <entry><literal>{red,orange,yellow,green}</literal></entry>
6951 <entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
6952 <entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
6959 Notice that except for the two-argument form of <function>enum_range</>,
6960 these functions disregard the specific value passed to them; they care
6961 only about its declared data type. Either null or a specific value of
6962 the type can be passed, with the same result. It is more common to
6963 apply these functions to a table column or function argument than to
6964 a hardwired type name as suggested by the examples.
6968 <sect1 id="functions-geometry
">
6969 <title>Geometric Functions and Operators</title>
6972 The geometric types <type>point</type>, <type>box</type>,
6973 <type>lseg</type>, <type>line</type>, <type>path</type>,
6974 <type>polygon</type>, and <type>circle</type> have a large set of
6975 native support functions and operators, shown in <xref
6976 linkend="functions-geometry-op-table
">, <xref
6977 linkend="functions-geometry-func-table
">, and <xref
6978 linkend="functions-geometry-conv-table
">.
6983 Note that the <quote>same as</> operator, <literal>~=</>, represents
6984 the usual notion of equality for the <type>point</type>,
6985 <type>box</type>, <type>polygon</type>, and <type>circle</type> types.
6986 Some of these types also have an <literal>=</> operator, but
6987 <literal>=</> compares
6988 for equal <emphasis>areas</> only. The other scalar comparison operators
6989 (<literal><=</> and so on) likewise compare areas for these types.
6993 <table id="functions-geometry-op-table
">
6994 <title>Geometric Operators</title>
6998 <entry>Operator</entry>
6999 <entry>Description</entry>
7000 <entry>Example</entry>
7005 <entry> <literal>+</literal> </entry>
7006 <entry>Translation</entry>
7007 <entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
7010 <entry> <literal>-</literal> </entry>
7011 <entry>Translation</entry>
7012 <entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
7015 <entry> <literal>*</literal> </entry>
7016 <entry>Scaling/rotation</entry>
7017 <entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
7020 <entry> <literal>/</literal> </entry>
7021 <entry>Scaling/rotation</entry>
7022 <entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
7025 <entry> <literal>#</literal> </entry>
7026 <entry>Point or box of intersection</entry>
7027 <entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
7030 <entry> <literal>#</literal> </entry>
7031 <entry>Number of points in path or polygon</entry>
7032 <entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
7035 <entry> <literal>@-@</literal> </entry>
7036 <entry>Length or circumference</entry>
7037 <entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
7040 <entry> <literal>@@</literal> </entry>
7041 <entry>Center</entry>
7042 <entry><literal>@@ circle '((0,0),10)'</literal></entry>
7045 <entry> <literal>##</literal> </entry>
7046 <entry>Closest point to first operand on second operand</entry>
7047 <entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
7050 <entry> <literal><-></literal> </entry>
7051 <entry>Distance between</entry>
7052 <entry><literal>circle '((0,0),1)' <-> circle '((5,0),1)'</literal></entry>
7055 <entry> <literal>&&</literal> </entry>
7056 <entry>Overlaps?</entry>
7057 <entry><literal>box '((0,0),(1,1))' && box '((0,0),(2,2))'</literal></entry>
7060 <entry> <literal><<</literal> </entry>
7061 <entry>Is strictly left of?</entry>
7062 <entry><literal>circle '((0,0),1)' << circle '((5,0),1)'</literal></entry>
7065 <entry> <literal>>></literal> </entry>
7066 <entry>Is strictly right of?</entry>
7067 <entry><literal>circle '((5,0),1)' >> circle '((0,0),1)'</literal></entry>
7070 <entry> <literal>&<</literal> </entry>
7071 <entry>Does not extend to the right of?</entry>
7072 <entry><literal>box '((0,0),(1,1))' &< box '((0,0),(2,2))'</literal></entry>
7075 <entry> <literal>&></literal> </entry>
7076 <entry>Does not extend to the left of?</entry>
7077 <entry><literal>box '((0,0),(3,3))' &> box '((0,0),(2,2))'</literal></entry>
7080 <entry> <literal><<|</literal> </entry>
7081 <entry>Is strictly below?</entry>
7082 <entry><literal>box '((0,0),(3,3))' <<| box '((3,4),(5,5))'</literal></entry>
7085 <entry> <literal>|>></literal> </entry>
7086 <entry>Is strictly above?</entry>
7087 <entry><literal>box '((3,4),(5,5))' |>> box '((0,0),(3,3))'</literal></entry>
7090 <entry> <literal>&<|</literal> </entry>
7091 <entry>Does not extend above?</entry>
7092 <entry><literal>box '((0,0),(1,1))' &<| box '((0,0),(2,2))'</literal></entry>
7095 <entry> <literal>|&></literal> </entry>
7096 <entry>Does not extend below?</entry>
7097 <entry><literal>box '((0,0),(3,3))' |&> box '((0,0),(2,2))'</literal></entry>
7100 <entry> <literal><^</literal> </entry>
7101 <entry>Is below (allows touching)?</entry>
7102 <entry><literal>circle '((0,0),1)' <^ circle '((0,5),1)'</literal></entry>
7105 <entry> <literal>>^</literal> </entry>
7106 <entry>Is above (allows touching)?</entry>
7107 <entry><literal>circle '((0,5),1)' >^ circle '((0,0),1)'</literal></entry>
7110 <entry> <literal>?#</literal> </entry>
7111 <entry>Intersects?</entry>
7112 <entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
7115 <entry> <literal>?-</literal> </entry>
7116 <entry>Is horizontal?</entry>
7117 <entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
7120 <entry> <literal>?-</literal> </entry>
7121 <entry>Are horizontally aligned?</entry>
7122 <entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
7125 <entry> <literal>?|</literal> </entry>
7126 <entry>Is vertical?</entry>
7127 <entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
7130 <entry> <literal>?|</literal> </entry>
7131 <entry>Are vertically aligned?</entry>
7132 <entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
7135 <entry> <literal>?-|</literal> </entry>
7136 <entry>Is perpendicular?</entry>
7137 <entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
7140 <entry> <literal>?||</literal> </entry>
7141 <entry>Are parallel?</entry>
7142 <entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
7145 <entry> <literal>@></literal> </entry>
7146 <entry>Contains?</entry>
7147 <entry><literal>circle '((0,0),2)' @> point '(1,1)'</literal></entry>
7150 <entry> <literal><@</literal> </entry>
7151 <entry>Contained in or on?</entry>
7152 <entry><literal>point '(1,1)' <@ circle '((0,0),2)'</literal></entry>
7155 <entry> <literal>~=</literal> </entry>
7156 <entry>Same as?</entry>
7157 <entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
7165 Before <productname>PostgreSQL</productname> 8.2, the containment
7166 operators <literal>@></> and <literal><@</> were respectively
7167 called <literal>~</> and <literal>@</>. These names are still
7168 available, but are deprecated and will eventually be removed.
7173 <primary>area</primary>
7176 <primary>center</primary>
7179 <primary>diameter</primary>
7182 <primary>height</primary>
7185 <primary>isclosed</primary>
7188 <primary>isopen</primary>
7191 <primary>length</primary>
7194 <primary>npoints</primary>
7197 <primary>pclose</primary>
7200 <primary>popen</primary>
7203 <primary>radius</primary>
7206 <primary>width</primary>
7209 <table id="functions-geometry-func-table
">
7210 <title>Geometric Functions</title>
7214 <entry>Function</entry>
7215 <entry>Return Type</entry>
7216 <entry>Description</entry>
7217 <entry>Example</entry>
7222 <entry><literal><function>area</function>(<replaceable>object</>)</literal></entry>
7223 <entry><type>double precision</type></entry>
7225 <entry><literal>area(box '((0,0),(1,1))')</literal></entry>
7228 <entry><literal><function>center</function>(<replaceable>object</>)</literal></entry>
7229 <entry><type>point</type></entry>
7230 <entry>center</entry>
7231 <entry><literal>center(box '((0,0),(1,2))')</literal></entry>
7234 <entry><literal><function>diameter</function>(<type>circle</>)</literal></entry>
7235 <entry><type>double precision</type></entry>
7236 <entry>diameter of circle</entry>
7237 <entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
7240 <entry><literal><function>height</function>(<type>box</>)</literal></entry>
7241 <entry><type>double precision</type></entry>
7242 <entry>vertical size of box</entry>
7243 <entry><literal>height(box '((0,0),(1,1))')</literal></entry>
7246 <entry><literal><function>isclosed</function>(<type>path</>)</literal></entry>
7247 <entry><type>boolean</type></entry>
7248 <entry>a closed path?</entry>
7249 <entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
7252 <entry><literal><function>isopen</function>(<type>path</>)</literal></entry>
7253 <entry><type>boolean</type></entry>
7254 <entry>an open path?</entry>
7255 <entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7258 <entry><literal><function>length</function>(<replaceable>object</>)</literal></entry>
7259 <entry><type>double precision</type></entry>
7260 <entry>length</entry>
7261 <entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
7264 <entry><literal><function>npoints</function>(<type>path</>)</literal></entry>
7265 <entry><type>int</type></entry>
7266 <entry>number of points</entry>
7267 <entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7270 <entry><literal><function>npoints</function>(<type>polygon</>)</literal></entry>
7271 <entry><type>int</type></entry>
7272 <entry>number of points</entry>
7273 <entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
7276 <entry><literal><function>pclose</function>(<type>path</>)</literal></entry>
7277 <entry><type>path</type></entry>
7278 <entry>convert path to closed</entry>
7279 <entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
7282 <!-- Not defined by this name. Implements the intersection operator '#' -->
7284 <entry><literal><function>point</function>(<type>lseg</>, <type>lseg</>)</literal></entry>
7285 <entry><type>point</type></entry>
7286 <entry>intersection</entry>
7287 <entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
7291 <entry><literal><function>popen</function>(<type>path</>)</literal></entry>
7292 <entry><type>path</type></entry>
7293 <entry>convert path to open</entry>
7294 <entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
7297 <entry><literal><function>radius</function>(<type>circle</type>)</literal></entry>
7298 <entry><type>double precision</type></entry>
7299 <entry>radius of circle</entry>
7300 <entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
7303 <entry><literal><function>width</function>(<type>box</>)</literal></entry>
7304 <entry><type>double precision</type></entry>
7305 <entry>horizontal size of box</entry>
7306 <entry><literal>width(box '((0,0),(1,1))')</literal></entry>
7312 <table id="functions-geometry-conv-table
">
7313 <title>Geometric Type Conversion Functions</title>
7317 <entry>Function</entry>
7318 <entry>Return Type</entry>
7319 <entry>Description</entry>
7320 <entry>Example</entry>
7325 <entry><literal><function>box</function>(<type>circle</type>)</literal></entry>
7326 <entry><type>box</type></entry>
7327 <entry>circle to box</entry>
7328 <entry><literal>box(circle '((0,0),2.0)')</literal></entry>
7331 <entry><literal><function>box</function>(<type>point</type>, <type>point</type>)</literal></entry>
7332 <entry><type>box</type></entry>
7333 <entry>points to box</entry>
7334 <entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
7337 <entry><literal><function>box</function>(<type>polygon</type>)</literal></entry>
7338 <entry><type>box</type></entry>
7339 <entry>polygon to box</entry>
7340 <entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7343 <entry><literal><function>circle</function>(<type>box</type>)</literal></entry>
7344 <entry><type>circle</type></entry>
7345 <entry>box to circle</entry>
7346 <entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
7349 <entry><literal><function>circle</function>(<type>point</type>, <type>double precision</type>)</literal></entry>
7350 <entry><type>circle</type></entry>
7351 <entry>center and radius to circle</entry>
7352 <entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
7355 <entry><literal><function>circle</function>(<type>polygon</type>)</literal></entry>
7356 <entry><type>circle</type></entry>
7357 <entry>polygon to circle</entry>
7358 <entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7361 <entry><literal><function>lseg</function>(<type>box</type>)</literal></entry>
7362 <entry><type>lseg</type></entry>
7363 <entry>box diagonal to line segment</entry>
7364 <entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
7367 <entry><literal><function>lseg</function>(<type>point</type>, <type>point</type>)</literal></entry>
7368 <entry><type>lseg</type></entry>
7369 <entry>points to line segment</entry>
7370 <entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
7373 <entry><literal><function>path</function>(<type>polygon</type>)</literal></entry>
7374 <entry><type>point</type></entry>
7375 <entry>polygon to path</entry>
7376 <entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7379 <entry><literal><function>point</function>(<type>double
7380 precision</type>, <type>double precision</type>)</literal></entry>
7381 <entry><type>point</type></entry>
7382 <entry>construct point</entry>
7383 <entry><literal>point(23.4, -44.5)</literal></entry>
7386 <entry><literal><function>point</function>(<type>box</type>)</literal></entry>
7387 <entry><type>point</type></entry>
7388 <entry>center of box</entry>
7389 <entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
7392 <entry><literal><function>point</function>(<type>circle</type>)</literal></entry>
7393 <entry><type>point</type></entry>
7394 <entry>center of circle</entry>
7395 <entry><literal>point(circle '((0,0),2.0)')</literal></entry>
7398 <entry><literal><function>point</function>(<type>lseg</type>)</literal></entry>
7399 <entry><type>point</type></entry>
7400 <entry>center of line segment</entry>
7401 <entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
7404 <entry><literal><function>point</function>(<type>polygon</type>)</literal></entry>
7405 <entry><type>point</type></entry>
7406 <entry>center of polygon</entry>
7407 <entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
7410 <entry><literal><function>polygon</function>(<type>box</type>)</literal></entry>
7411 <entry><type>polygon</type></entry>
7412 <entry>box to 4-point polygon</entry>
7413 <entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
7416 <entry><literal><function>polygon</function>(<type>circle</type>)</literal></entry>
7417 <entry><type>polygon</type></entry>
7418 <entry>circle to 12-point polygon</entry>
7419 <entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
7422 <entry><literal><function>polygon</function>(<replaceable class="parameter
">npts</replaceable>, <type>circle</type>)</literal></entry>
7423 <entry><type>polygon</type></entry>
7424 <entry>circle to <replaceable class="parameter
">npts</replaceable>-point polygon</entry>
7425 <entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
7428 <entry><literal><function>polygon</function>(<type>path</type>)</literal></entry>
7429 <entry><type>polygon</type></entry>
7430 <entry>path to polygon</entry>
7431 <entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
7438 It is possible to access the two component numbers of a <type>point</>
7439 as though the point were an array with indexes 0 and 1. For example, if
7440 <literal>t.p</> is a <type>point</> column then
7441 <literal>SELECT p[0] FROM t</> retrieves the X coordinate and
7442 <literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
7443 In the same way, a value of type <type>box</> or <type>lseg</> can be treated
7444 as an array of two <type>point</> values.
7448 The <function>area</function> function works for the types
7449 <type>box</type>, <type>circle</type>, and <type>path</type>.
7450 The <function>area</function> function only works on the
7451 <type>path</type> data type if the points in the
7452 <type>path</type> are non-intersecting. For example, the
7454 <literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
7455 will not work; however, the following visually identical
7457 <literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
7458 will work. If the concept of an intersecting versus
7459 non-intersecting <type>path</type> is confusing, draw both of the
7460 above <type>path</type>s side by side on a piece of graph paper.
7466 <sect1 id="functions-net
">
7467 <title>Network Address Functions and Operators</title>
7470 <xref linkend="cidr-inet-operators-table
"> shows the operators
7471 available for the <type>cidr</type> and <type>inet</type> types.
7472 The operators <literal><<</literal>,
7473 <literal><<=</literal>, <literal>>></literal>, and
7474 <literal>>>=</literal> test for subnet inclusion. They
7475 consider only the network parts of the two addresses (ignoring any
7476 host part) and determine whether one network is identical to
7477 or a subnet of the other.
7480 <table id="cidr-inet-operators-table
">
7481 <title><type>cidr</type> and <type>inet</type> Operators</title>
7485 <entry>Operator</entry>
7486 <entry>Description</entry>
7487 <entry>Example</entry>
7492 <entry> <literal><</literal> </entry>
7493 <entry>is less than</entry>
7494 <entry><literal>inet '192.168.1.5' < inet '192.168.1.6'</literal></entry>
7497 <entry> <literal><=</literal> </entry>
7498 <entry>is less than or equal</entry>
7499 <entry><literal>inet '192.168.1.5' <= inet '192.168.1.5'</literal></entry>
7502 <entry> <literal>=</literal> </entry>
7503 <entry>equals</entry>
7504 <entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
7507 <entry> <literal>>=</literal> </entry>
7508 <entry>is greater or equal</entry>
7509 <entry><literal>inet '192.168.1.5' >= inet '192.168.1.5'</literal></entry>
7512 <entry> <literal>></literal> </entry>
7513 <entry>is greater than</entry>
7514 <entry><literal>inet '192.168.1.5' > inet '192.168.1.4'</literal></entry>
7517 <entry> <literal><></literal> </entry>
7518 <entry>is not equal</entry>
7519 <entry><literal>inet '192.168.1.5' <> inet '192.168.1.4'</literal></entry>
7522 <entry> <literal><<</literal> </entry>
7523 <entry>is contained within</entry>
7524 <entry><literal>inet '192.168.1.5' << inet '192.168.1/24'</literal></entry>
7527 <entry> <literal><<=</literal> </entry>
7528 <entry>is contained within or equals</entry>
7529 <entry><literal>inet '192.168.1/24' <<= inet '192.168.1/24'</literal></entry>
7532 <entry> <literal>>></literal> </entry>
7533 <entry>contains</entry>
7534 <entry><literal>inet '192.168.1/24' >> inet '192.168.1.5'</literal></entry>
7537 <entry> <literal>>>=</literal> </entry>
7538 <entry>contains or equals</entry>
7539 <entry><literal>inet '192.168.1/24' >>= inet '192.168.1/24'</literal></entry>
7542 <entry> <literal>~</literal> </entry>
7543 <entry>bitwise NOT</entry>
7544 <entry><literal>~ inet '192.168.1.6'</literal></entry>
7547 <entry> <literal>&</literal> </entry>
7548 <entry>bitwise AND</entry>
7549 <entry><literal>inet '192.168.1.6' & inet '0.0.0.255'</literal></entry>
7552 <entry> <literal>|</literal> </entry>
7553 <entry>bitwise OR</entry>
7554 <entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
7557 <entry> <literal>+</literal> </entry>
7558 <entry>addition</entry>
7559 <entry><literal>inet '192.168.1.6' + 25</literal></entry>
7562 <entry> <literal>-</literal> </entry>
7563 <entry>subtraction</entry>
7564 <entry><literal>inet '192.168.1.43' - 36</literal></entry>
7567 <entry> <literal>-</literal> </entry>
7568 <entry>subtraction</entry>
7569 <entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
7576 <xref linkend="cidr-inet-functions-table
"> shows the functions
7577 available for use with the <type>cidr</type> and <type>inet</type>
7578 types. The <function>abbrev</function>, <function>host</function>,
7579 and <function>text</function>
7580 functions are primarily intended to offer alternative display
7584 <table id="cidr-inet-functions-table
">
7585 <title><type>cidr</type> and <type>inet</type> Functions</title>
7589 <entry>Function</entry>
7590 <entry>Return Type</entry>
7591 <entry>Description</entry>
7592 <entry>Example</entry>
7593 <entry>Result</entry>
7598 <entry><literal><function>abbrev</function>(<type>inet</type>)</literal></entry>
7599 <entry><type>text</type></entry>
7600 <entry>abbreviated display format as text</entry>
7601 <entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
7602 <entry><literal>10.1.0.0/16</literal></entry>
7605 <entry><literal><function>abbrev</function>(<type>cidr</type>)</literal></entry>
7606 <entry><type>text</type></entry>
7607 <entry>abbreviated display format as text</entry>
7608 <entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
7609 <entry><literal>10.1/16</literal></entry>
7612 <entry><literal><function>broadcast</function>(<type>inet</type>)</literal></entry>
7613 <entry><type>inet</type></entry>
7614 <entry>broadcast address for network</entry>
7615 <entry><literal>broadcast('192.168.1.5/24')</literal></entry>
7616 <entry><literal>192.168.1.255/24</literal></entry>
7619 <entry><literal><function>family</function>(<type>inet</type>)</literal></entry>
7620 <entry><type>int</type></entry>
7621 <entry>extract family of address; <literal>4</literal> for IPv4,
7622 <literal>6</literal> for IPv6</entry>
7623 <entry><literal>family('::1')</literal></entry>
7624 <entry><literal>6</literal></entry>
7627 <entry><literal><function>host</function>(<type>inet</type>)</literal></entry>
7628 <entry><type>text</type></entry>
7629 <entry>extract IP address as text</entry>
7630 <entry><literal>host('192.168.1.5/24')</literal></entry>
7631 <entry><literal>192.168.1.5</literal></entry>
7634 <entry><literal><function>hostmask</function>(<type>inet</type>)</literal></entry>
7635 <entry><type>inet</type></entry>
7636 <entry>construct host mask for network</entry>
7637 <entry><literal>hostmask('192.168.23.20/30')</literal></entry>
7638 <entry><literal>0.0.0.3</literal></entry>
7641 <entry><literal><function>masklen</function>(<type>inet</type>)</literal></entry>
7642 <entry><type>int</type></entry>
7643 <entry>extract netmask length</entry>
7644 <entry><literal>masklen('192.168.1.5/24')</literal></entry>
7645 <entry><literal>24</literal></entry>
7648 <entry><literal><function>netmask</function>(<type>inet</type>)</literal></entry>
7649 <entry><type>inet</type></entry>
7650 <entry>construct netmask for network</entry>
7651 <entry><literal>netmask('192.168.1.5/24')</literal></entry>
7652 <entry><literal>255.255.255.0</literal></entry>
7655 <entry><literal><function>network</function>(<type>inet</type>)</literal></entry>
7656 <entry><type>cidr</type></entry>
7657 <entry>extract network part of address</entry>
7658 <entry><literal>network('192.168.1.5/24')</literal></entry>
7659 <entry><literal>192.168.1.0/24</literal></entry>
7662 <entry><literal><function>set_masklen</function>(<type>inet</type>, <type>int</type>)</literal></entry>
7663 <entry><type>inet</type></entry>
7664 <entry>set netmask length for <type>inet</type> value</entry>
7665 <entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
7666 <entry><literal>192.168.1.5/16</literal></entry>
7669 <entry><literal><function>set_masklen</function>(<type>cidr</type>, <type>int</type>)</literal></entry>
7670 <entry><type>cidr</type></entry>
7671 <entry>set netmask length for <type>cidr</type> value</entry>
7672 <entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
7673 <entry><literal>192.168.0.0/16</literal></entry>
7676 <entry><literal><function>text</function>(<type>inet</type>)</literal></entry>
7677 <entry><type>text</type></entry>
7678 <entry>extract IP address and netmask length as text</entry>
7679 <entry><literal>text(inet '192.168.1.5')</literal></entry>
7680 <entry><literal>192.168.1.5/32</literal></entry>
7687 Any <type>cidr</> value can be cast to <type>inet</> implicitly
7688 or explicitly; therefore, the functions shown above as operating on
7689 <type>inet</> also work on <type>cidr</> values. (Where there are
7690 separate functions for <type>inet</> and <type>cidr</>, it is because
7691 the behavior should be different for the two cases.)
7692 Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
7693 When this is done, any bits to the right of the netmask are silently zeroed
7694 to create a valid <type>cidr</> value.
7696 you can cast a text value to <type>inet</> or <type>cidr</>
7697 using normal casting syntax: for example,
7698 <literal>inet(<replaceable>expression</>)</literal> or
7699 <literal><replaceable>colname</>::cidr</literal>.
7703 <xref linkend="macaddr-functions-table
"> shows the functions
7704 available for use with the <type>macaddr</type> type. The function
7705 <literal><function>trunc</function>(<type>macaddr</type>)</literal> returns a MAC
7706 address with the last 3 bytes set to zero. This can be used to
7707 associate the remaining prefix with a manufacturer.
7710 <table id="macaddr-functions-table
">
7711 <title><type>macaddr</type> Functions</title>
7715 <entry>Function</entry>
7716 <entry>Return Type</entry>
7717 <entry>Description</entry>
7718 <entry>Example</entry>
7719 <entry>Result</entry>
7724 <entry><literal><function>trunc</function>(<type>macaddr</type>)</literal></entry>
7725 <entry><type>macaddr</type></entry>
7726 <entry>set last 3 bytes to zero</entry>
7727 <entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
7728 <entry><literal>12:34:56:00:00:00</literal></entry>
7735 The <type>macaddr</type> type also supports the standard relational
7736 operators (<literal>></literal>, <literal><=</literal>, etc.) for
7737 lexicographical ordering.
7743 <sect1 id="functions-textsearch
">
7744 <title>Text Search Functions and Operators</title>
7746 <indexterm zone="datatype-textsearch
">
7747 <primary>full text search</primary>
7748 <secondary>functions and operators</secondary>
7751 <indexterm zone="datatype-textsearch
">
7752 <primary>text search</primary>
7753 <secondary>functions and operators</secondary>
7757 <xref linkend="textsearch-operators-table
">,
7758 <xref linkend="textsearch-functions-table
"> and
7759 <xref linkend="textsearch-functions-debug-table
">
7760 summarize the functions and operators that are provided
7761 for full text searching. See <xref linkend="textsearch
"> for a detailed
7762 explanation of <productname>PostgreSQL</productname>'s text search
7766 <table id="textsearch-operators-table
">
7767 <title>Text Search Operators</title>
7771 <entry>Operator</entry>
7772 <entry>Description</entry>
7773 <entry>Example</entry>
7774 <entry>Result</entry>
7779 <entry> <literal>@@</literal> </entry>
7780 <entry><type>tsvector</> matches <type>tsquery</> ?</entry>
7781 <entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat & rat')</literal></entry>
7782 <entry><literal>t</literal></entry>
7785 <entry> <literal>@@@</literal> </entry>
7786 <entry>deprecated synonym for <literal>@@</></entry>
7787 <entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat & rat')</literal></entry>
7788 <entry><literal>t</literal></entry>
7791 <entry> <literal>||</literal> </entry>
7792 <entry>concatenate <type>tsvector</>s</entry>
7793 <entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
7794 <entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
7797 <entry> <literal>&&</literal> </entry>
7798 <entry>AND <type>tsquery</>s together</entry>
7799 <entry><literal>'fat | rat'::tsquery && 'cat'::tsquery</literal></entry>
7800 <entry><literal>( 'fat' | 'rat' ) & 'cat'</literal></entry>
7803 <entry> <literal>||</literal> </entry>
7804 <entry>OR <type>tsquery</>s together</entry>
7805 <entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
7806 <entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
7809 <entry> <literal>!!</literal> </entry>
7810 <entry>negate a <type>tsquery</></entry>
7811 <entry><literal>!! 'cat'::tsquery</literal></entry>
7812 <entry><literal>!'cat'</literal></entry>
7815 <entry> <literal>@></literal> </entry>
7816 <entry><type>tsquery</> contains another ?</entry>
7817 <entry><literal>'cat'::tsquery @> 'cat & rat'::tsquery</literal></entry>
7818 <entry><literal>f</literal></entry>
7821 <entry> <literal><@</literal> </entry>
7822 <entry><type>tsquery</> is contained in ?</entry>
7823 <entry><literal>'cat'::tsquery <@ 'cat & rat'::tsquery</literal></entry>
7824 <entry><literal>t</literal></entry>
7832 The <type>tsquery</> containment operators consider only the lexemes
7833 listed in the two queries, ignoring the combining operators.
7838 In addition to the operators shown in the table, the ordinary B-tree
7839 comparison operators (<literal>=</>, <literal><</>, etc) are defined
7840 for types <type>tsvector</> and <type>tsquery</>. These are not very
7841 useful for text searching but allow, for example, unique indexes to be
7842 built on columns of these types.
7845 <table id="textsearch-functions-table
">
7846 <title>Text Search Functions</title>
7850 <entry>Function</entry>
7851 <entry>Return Type</entry>
7852 <entry>Description</entry>
7853 <entry>Example</entry>
7854 <entry>Result</entry>
7859 <entry><literal><function>to_tsvector</function>(<optional> <replaceable class="PARAMETER
">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER
">document</> <type>text</type>)</literal></entry>
7860 <entry><type>tsvector</type></entry>
7861 <entry>reduce document text to <type>tsvector</></entry>
7862 <entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
7863 <entry><literal>'fat':2 'rat':3</literal></entry>
7866 <entry><literal><function>length</function>(<type>tsvector</>)</literal></entry>
7867 <entry><type>integer</type></entry>
7868 <entry>number of lexemes in <type>tsvector</></entry>
7869 <entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7870 <entry><literal>3</literal></entry>
7873 <entry><literal><function>setweight</function>(<type>tsvector</>, <type>"char
"</>)</literal></entry>
7874 <entry><type>tsvector</type></entry>
7875 <entry>assign weight to each element of <type>tsvector</></entry>
7876 <entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
7877 <entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
7880 <entry><literal><function>strip</function>(<type>tsvector</>)</literal></entry>
7881 <entry><type>tsvector</type></entry>
7882 <entry>remove positions and weights from <type>tsvector</></entry>
7883 <entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
7884 <entry><literal>'cat' 'fat' 'rat'</literal></entry>
7887 <entry><literal><function>to_tsquery</function>(<optional> <replaceable class="PARAMETER
">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER
">query</> <type>text</type>)</literal></entry>
7888 <entry><type>tsquery</type></entry>
7889 <entry>normalize words and convert to <type>tsquery</></entry>
7890 <entry><literal>to_tsquery('english', 'The & Fat & Rats')</literal></entry>
7891 <entry><literal>'fat' & 'rat'</literal></entry>
7894 <entry><literal><function>plainto_tsquery</function>(<optional> <replaceable class="PARAMETER
">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER
">query</> <type>text</type>)</literal></entry>
7895 <entry><type>tsquery</type></entry>
7896 <entry>produce <type>tsquery</> ignoring punctuation</entry>
7897 <entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
7898 <entry><literal>'fat' & 'rat'</literal></entry>
7901 <entry><literal><function>numnode</function>(<type>tsquery</>)</literal></entry>
7902 <entry><type>integer</type></entry>
7903 <entry>number of lexemes plus operators in <type>tsquery</></entry>
7904 <entry><literal> numnode('(fat & rat) | cat'::tsquery)</literal></entry>
7905 <entry><literal>5</literal></entry>
7908 <entry><literal><function>querytree</function>(<replaceable class="PARAMETER
">query</replaceable> <type>tsquery</>)</literal></entry>
7909 <entry><type>text</type></entry>
7910 <entry>get indexable part of a <type>tsquery</></entry>
7911 <entry><literal>querytree('foo & ! bar'::tsquery)</literal></entry>
7912 <entry><literal>'foo'</literal></entry>
7915 <entry><literal><function>ts_rank</function>(<optional> <replaceable class="PARAMETER
">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER
">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER
">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER
">normalization</replaceable> <type>integer</> </optional>)</literal></entry>
7916 <entry><type>float4</type></entry>
7917 <entry>rank document for query</entry>
7918 <entry><literal>ts_rank(textsearch, query)</literal></entry>
7919 <entry><literal>0.818</literal></entry>
7922 <entry><literal><function>ts_rank_cd</function>(<optional> <replaceable class="PARAMETER
">weights</replaceable> <type>float4[]</>, </optional> <replaceable class="PARAMETER
">vector</replaceable> <type>tsvector</>, <replaceable class="PARAMETER
">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER
">normalization</replaceable> <type>integer</> </optional>)</literal></entry>
7923 <entry><type>float4</type></entry>
7924 <entry>rank document for query using cover density</entry>
7925 <entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
7926 <entry><literal>2.01317</literal></entry>
7929 <entry><literal><function>ts_headline</function>(<optional> <replaceable class="PARAMETER
">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER
">document</replaceable> <type>text</>, <replaceable class="PARAMETER
">query</replaceable> <type>tsquery</> <optional>, <replaceable class="PARAMETER
">options</replaceable> <type>text</> </optional>)</literal></entry>
7930 <entry><type>text</type></entry>
7931 <entry>display a query match</entry>
7932 <entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
7933 <entry><literal>x y <b>z</b></literal></entry>
7936 <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER
">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER
">target</replaceable> <type>tsquery</>, <replaceable class="PARAMETER
">substitute</replaceable> <type>tsquery</>)</literal></entry>
7937 <entry><type>tsquery</type></entry>
7938 <entry>replace target with substitute within query</entry>
7939 <entry><literal>ts_rewrite('a & b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
7940 <entry><literal>'b' & ( 'foo' | 'bar' )</literal></entry>
7943 <entry><literal><function>ts_rewrite</function>(<replaceable class="PARAMETER
">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER
">select</replaceable> <type>text</>)</literal></entry>
7944 <entry><type>tsquery</type></entry>
7945 <entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
7946 <entry><literal>SELECT ts_rewrite('a & b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
7947 <entry><literal>'b' & ( 'foo' | 'bar' )</literal></entry>
7950 <entry><literal><function>get_current_ts_config</function>()</literal></entry>
7951 <entry><type>regconfig</type></entry>
7952 <entry>get default text search configuration</entry>
7953 <entry><literal>get_current_ts_config()</literal></entry>
7954 <entry><literal>english</literal></entry>
7957 <entry><literal><function>tsvector_update_trigger</function>()</literal></entry>
7958 <entry><type>trigger</type></entry>
7959 <entry>trigger function for automatic <type>tsvector</> column update</entry>
7960 <entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
7961 <entry><literal></literal></entry>
7964 <entry><literal><function>tsvector_update_trigger_column</function>()</literal></entry>
7965 <entry><type>trigger</type></entry>
7966 <entry>trigger function for automatic <type>tsvector</> column update</entry>
7967 <entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
7968 <entry><literal></literal></entry>
7969 <entry><literal></literal></entry>
7977 All the text search functions that accept an optional <type>regconfig</>
7978 argument will use the configuration specified by
7979 <xref linkend="guc-default-text-search-config
">
7980 when that argument is omitted.
7986 <xref linkend="textsearch-functions-debug-table
">
7987 are listed separately because they are not usually used in everyday text
7988 searching operations. They are helpful for development and debugging
7989 of new text search configurations.
7992 <table id="textsearch-functions-debug-table
">
7993 <title>Text Search Debugging Functions</title>
7997 <entry>Function</entry>
7998 <entry>Return Type</entry>
7999 <entry>Description</entry>
8000 <entry>Example</entry>
8001 <entry>Result</entry>
8006 <entry><literal><function>ts_debug</function>(<optional> <replaceable class="PARAMETER
">config</replaceable> <type>regconfig</>, </optional> <replaceable class="PARAMETER
">document</replaceable> <type>text</>, OUT <replaceable class="PARAMETER
">alias</> <type>text</>, OUT <replaceable class="PARAMETER
">description</> <type>text</>, OUT <replaceable class="PARAMETER
">token</> <type>text</>, OUT <replaceable class="PARAMETER
">dictionaries</> <type>regdictionary[]</>, OUT <replaceable class="PARAMETER
">dictionary</> <type>regdictionary</>, OUT <replaceable class="PARAMETER
">lexemes</> <type>text[]</>)</literal></entry>
8007 <entry><type>setof record</type></entry>
8008 <entry>test a configuration</entry>
8009 <entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
8010 <entry><literal>(asciiword,"Word, all ASCII
",The,{english_stem},english_stem,{}) ...</literal></entry>
8013 <entry><literal><function>ts_lexize</function>(<replaceable class="PARAMETER
">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER
">token</replaceable> <type>text</>)</literal></entry>
8014 <entry><type>text[]</type></entry>
8015 <entry>test a dictionary</entry>
8016 <entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
8017 <entry><literal>{star}</literal></entry>
8020 <entry><literal><function>ts_parse</function>(<replaceable class="PARAMETER
">parser_name</replaceable> <type>text</>, <replaceable class="PARAMETER
">document</replaceable> <type>text</>, OUT <replaceable class="PARAMETER
">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER
">token</> <type>text</>)</literal></entry>
8021 <entry><type>setof record</type></entry>
8022 <entry>test a parser</entry>
8023 <entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
8024 <entry><literal>(1,foo) ...</literal></entry>
8027 <entry><literal><function>ts_parse</function>(<replaceable class="PARAMETER
">parser_oid</replaceable> <type>oid</>, <replaceable class="PARAMETER
">document</replaceable> <type>text</>, OUT <replaceable class="PARAMETER
">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER
">token</> <type>text</>)</literal></entry>
8028 <entry><type>setof record</type></entry>
8029 <entry>test a parser</entry>
8030 <entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
8031 <entry><literal>(1,foo) ...</literal></entry>
8034 <entry><literal><function>ts_token_type</function>(<replaceable class="PARAMETER
">parser_name</> <type>text</>, OUT <replaceable class="PARAMETER
">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER
">alias</> <type>text</>, OUT <replaceable class="PARAMETER
">description</> <type>text</>)</literal></entry>
8035 <entry><type>setof record</type></entry>
8036 <entry>get token types defined by parser</entry>
8037 <entry><literal>ts_token_type('default')</literal></entry>
8038 <entry><literal>(1,asciiword,"Word, all ASCII
") ...</literal></entry>
8041 <entry><literal><function>ts_token_type</function>(<replaceable class="PARAMETER
">parser_oid</> <type>oid</>, OUT <replaceable class="PARAMETER
">tokid</> <type>integer</>, OUT <replaceable class="PARAMETER
">alias</> <type>text</>, OUT <replaceable class="PARAMETER
">description</> <type>text</>)</literal></entry>
8042 <entry><type>setof record</type></entry>
8043 <entry>get token types defined by parser</entry>
8044 <entry><literal>ts_token_type(3722)</literal></entry>
8045 <entry><literal>(1,asciiword,"Word, all ASCII
") ...</literal></entry>
8048 <entry><literal><function>ts_stat</function>(<replaceable class="PARAMETER
">sqlquery</replaceable> <type>text</>, <optional> <replaceable class="PARAMETER
">weights</replaceable> <type>text</>, </optional> OUT <replaceable class="PARAMETER
">word</replaceable> <type>text</>, OUT <replaceable class="PARAMETER
">ndoc</replaceable> <type>integer</>, OUT <replaceable class="PARAMETER
">nentry</replaceable> <type>integer</>)</literal></entry>
8049 <entry><type>setof record</type></entry>
8050 <entry>get statistics of a <type>tsvector</> column</entry>
8051 <entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
8052 <entry><literal>(foo,10,15) ...</literal></entry>
8061 <sect1 id="functions-xml
">
8062 <title>XML Functions</title>
8065 The functions and function-like expressions described in this
8066 section operate on values of type <type>xml</type>. Check <xref
8067 linkend="datatype-xml
"> for information about the <type>xml</type>
8068 type. The function-like expressions <function>xmlparse</function>
8069 and <function>xmlserialize</function> for converting to and from
8070 type <type>xml</type> are not repeated here. Use of many of these
8071 functions requires the installation to have been built
8072 with <command>configure --with-libxml</>.
8076 <title>Producing XML Content</title>
8079 A set of functions and function-like expressions are available for
8080 producing XML content from SQL data. As such, they are
8081 particularly suitable for formatting query results into XML
8082 documents for processing in client applications.
8086 <title><literal>xmlcomment</literal></title>
8089 <primary>xmlcomment</primary>
8093 <function>xmlcomment</function>(<replaceable>text</replaceable>)
8097 The function <function>xmlcomment</function> creates an XML value
8098 containing an XML comment with the specified text as content.
8099 The text cannot contain <quote><literal>--</literal></quote> or end with a
8100 <quote><literal>-</literal></quote> so that the resulting construct is a valid
8101 XML comment. If the argument is null, the result is null.
8107 SELECT xmlcomment('hello');
8117 <title><literal>xmlconcat</literal></title>
8120 <primary>xmlconcat</primary>
8124 <function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
8128 The function <function>xmlconcat</function> concatenates a list
8129 of individual XML values to create a single value containing an
8130 XML content fragment. Null values are omitted; the result is
8131 only null if there are no nonnull arguments.
8137 SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
8140 ----------------------
8141 <abc/><bar>foo</bar>
8146 XML declarations, if present, are combined as follows. If all
8147 argument values have the same XML version declaration, that
8148 version is used in the result, else no version is used. If all
8149 argument values have the standalone declaration value
8150 <quote>yes</quote>, then that value is used in the result. If
8151 all argument values have a standalone declaration value and at
8152 least one is <quote>no</quote>, then that is used in the result.
8153 Else the result will have no standalone declaration. If the
8154 result is determined to require a standalone declaration but no
8155 version declaration, a version declaration with version 1.0 will
8156 be used because XML requires an XML declaration to contain a
8157 version declaration. Encoding declarations are ignored and
8158 removed in all cases.
8164 SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no
"?><bar/>');
8167 -----------------------------------
8168 <?xml version="1.1"?><foo/><bar/>
8174 <title><literal>xmlelement</literal></title>
8177 <primary>xmlelement</primary>
8181 <function>xmlelement</function>(name <replaceable>name</replaceable> <optional>, xmlattributes(<replaceable>value</replaceable> <optional>AS <replaceable>attname</replaceable></optional> <optional>, ... </optional>)</optional> <optional><replaceable>, content, ...</replaceable></optional>)
8185 The <function>xmlelement</function> expression produces an XML
8186 element with the given name, attributes, and content.
8192 SELECT xmlelement(name foo);
8198 SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
8204 SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
8207 -------------------------------------
8208 <foo bar="2007-
01-
26">content</foo>
8213 Element and attribute names that are not valid XML names are
8214 escaped by replacing the offending characters by the sequence
8215 <literal>_x<replaceable>HHHH</replaceable>_</literal>, where
8216 <replaceable>HHHH</replaceable> is the character's Unicode
8217 codepoint in hexadecimal notation. For example:
8219 SELECT xmlelement(name "foo$bar
", xmlattributes('xyz' as "a&b
"));
8222 ----------------------------------
8223 <foo_x0024_bar a_x0026_b="xyz
"/>
8228 An explicit attribute name need not be specified if the attribute
8229 value is a column reference, in which case the column's name will
8230 be used as the attribute name by default. In other cases, the
8231 attribute must be given an explicit name. So this example is
8234 CREATE TABLE test (a xml, b xml);
8235 SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
8239 SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
8240 SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
8245 Element content, if specified, will be formatted according to
8246 its data type. If the content is itself of type <type>xml</type>,
8247 complex XML documents can be constructed. For example:
8249 SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
8250 xmlelement(name abc),
8252 xmlelement(name xyz));
8255 ----------------------------------------------
8256 <foo bar="xyz
"><abc/><!--test--><xyz/></foo>
8259 Content of other types will be formatted into valid XML character
8260 data. This means in particular that the characters <, >,
8261 and & will be converted to entities. Binary data (data type
8262 <type>bytea</type>) will be represented in base64 or hex
8263 encoding, depending on the setting of the configuration parameter
8264 <xref linkend="guc-xmlbinary
">. The particular behavior for
8265 individual data types is expected to evolve in order to align the
8266 SQL and PostgreSQL data types with the XML Schema specification,
8267 at which point a more precise description will appear.
8272 <title><literal>xmlforest</literal></title>
8275 <primary>xmlforest</primary>
8279 <function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
8283 The <function>xmlforest</function> expression produces an XML
8284 forest (sequence) of elements using the given names and content.
8290 SELECT xmlforest('abc' AS foo, 123 AS bar);
8293 ------------------------------
8294 <foo>abc</foo><bar>123</bar>
8297 SELECT xmlforest(table_name, column_name)
8298 FROM information_schema.columns
8299 WHERE table_schema = 'pg_catalog';
8302 -------------------------------------------------------------------------------------------
8303 <table_name>pg_authid</table_name><column_name>rolname</column_name>
8304 <table_name>pg_authid</table_name><column_name>rolsuper</column_name>
8308 As seen in the second example, the element name can be omitted if
8309 the content value is a column reference, in which case the column
8310 name is used by default. Otherwise, a name must be specified.
8314 Element names that are not valid XML names are escaped as shown
8315 for <function>xmlelement</function> above. Similarly, content
8316 data is escaped to make valid XML content, unless it is already
8317 of type <type>xml</type>.
8321 Note that XML forests are not valid XML documents if they consist
8322 of more than one element, so it might be useful to wrap
8323 <function>xmlforest</function> expressions in
8324 <function>xmlelement</function>.
8329 <title><literal>xmlpi</literal></title>
8332 <primary>xmlpi</primary>
8336 <function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
8340 The <function>xmlpi</function> expression creates an XML
8341 processing instruction. The content, if present, must not
8342 contain the character sequence <literal>?></literal>.
8348 SELECT xmlpi(name php, 'echo "hello world
";');
8351 -----------------------------
8352 <?php echo "hello world
";?>
8358 <title><literal>xmlroot</literal></title>
8361 <primary>xmlroot</primary>
8365 <function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
8369 The <function>xmlroot</function> expression alters the properties
8370 of the root node of an XML value. If a version is specified,
8371 it replaces the value in the root node's version declaration; if a
8372 standalone setting is specified, it replaces the value in the
8373 root node's standalone declaration.
8378 SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
8379 version '1.0', standalone yes);
8382 ----------------------------------------
8383 <?xml version="1.0" standalone="yes
"?>
8384 <content>abc</content>
8389 <sect3 id="functions-xml-xmlagg
">
8390 <title><literal>xmlagg</literal></title>
8393 <primary>xmlagg</primary>
8397 <function>xmlagg</function>(<replaceable>xml</replaceable>)
8401 The function <function>xmlagg</function> is, unlike the other
8402 functions described here, an aggregate function. It concatenates the
8403 input values to the aggregate function call,
8404 like <function>xmlconcat</function> does.
8405 See <xref linkend="functions-aggregate
"> for additional information
8406 about aggregate functions.
8412 CREATE TABLE test (y int, x xml);
8413 INSERT INTO test VALUES (1, '<foo>abc</foo>');
8414 INSERT INTO test VALUES (2, '<bar/>');
8415 SELECT xmlagg(x) FROM test;
8417 ----------------------
8418 <foo>abc</foo><bar/>
8423 To determine the order of the concatenation, something like the
8424 following approach can be used:
8427 SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
8429 ----------------------
8430 <bar/><foo>abc</foo>
8433 Again, see <xref linkend="functions-aggregate
"> for additional
8439 <title>XML Predicates</title>
8442 <primary>IS DOCUMENT</primary>
8446 <replaceable>xml</replaceable> IS DOCUMENT
8450 The expression <literal>IS DOCUMENT</literal> returns true if the
8451 argument XML value is a proper XML document, false if it is not
8452 (that is, it is a content fragment), or null if the argument is
8453 null. See <xref linkend="datatype-xml
"> about the difference
8454 between documents and content fragments.
8459 <sect2 id="functions-xml-processing
">
8460 <title>Processing XML</title>
8463 <primary>XPath</primary>
8467 To process values of data type <type>xml</type>, PostgreSQL offers
8468 the function <function>xpath</function>, which evaluates XPath 1.0
8473 <function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable><optional>, <replaceable>nsarray</replaceable></optional>)
8477 The function <function>xpath</function> evaluates the XPath
8478 expression <replaceable>xpath</replaceable> against the XML value
8479 <replaceable>xml</replaceable>. It returns an array of XML values
8480 corresponding to the node set produced by the XPath expression.
8484 The second argument must be a well formed XML document. In particular,
8485 it must have a single root node element.
8489 The third argument of the function is an array of namespace
8490 mappings. This array should be a two-dimensional array with the
8491 length of the second axis being equal to 2 (i.e., it should be an
8492 array of arrays, each of which consists of exactly 2 elements).
8493 The first element of each array entry is the namespace name, the
8494 second the namespace URI.
8500 SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com
">test</my:a>',
8501 ARRAY[ARRAY['my', 'http://example.com']]);
8511 <sect2 id="functions-xml-mapping
">
8512 <title>Mapping Tables to XML</title>
8514 <indexterm zone="functions-xml-mapping
">
8515 <primary>XML export</primary>
8519 The following functions map the contents of relational tables to
8520 XML values. They can be thought of as XML export functionality:
8522 table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8523 query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
8524 cursor_to_xml(cursor refcursor, count int, nulls boolean,
8525 tableforest boolean, targetns text)
8527 The return type of each function is <type>xml</type>.
8531 <function>table_to_xml</function> maps the content of the named
8532 table, passed as parameter <parameter>tbl</parameter>. The
8533 <type>regclass</type> type accepts strings identifying tables using the
8534 usual notation, including optional schema qualifications and
8535 double quotes. <function>query_to_xml</function> executes the
8536 query whose text is passed as parameter
8537 <parameter>query</parameter> and maps the result set.
8538 <function>cursor_to_xml</function> fetches the indicated number of
8539 rows from the cursor specified by the parameter
8540 <parameter>cursor</parameter>. This variant is recommended if
8541 large tables have to be mapped, because the result value is built
8542 up in memory by each function.
8546 If <parameter>tableforest</parameter> is false, then the resulting
8547 XML document looks like this:
8551 <columnname1>data</columnname1>
8552 <columnname2>data</columnname2>
8563 If <parameter>tableforest</parameter> is true, the result is an
8564 XML content fragment that looks like this:
8567 <columnname1>data</columnname1>
8568 <columnname2>data</columnname2>
8578 If no table name is available, that is, when mapping a query or a
8579 cursor, the string <literal>table</literal> is used in the first
8580 format, <literal>row</literal> in the second format.
8584 The choice between these formats is up to the user. The first
8585 format is a proper XML document, which will be important in many
8586 applications. The second format tends to be more useful in the
8587 <function>cursor_to_xml</function> function if the result values are to be
8588 reassembled into one document later on. The functions for
8589 producing XML content discussed above, in particular
8590 <function>xmlelement</function>, can be used to alter the results
8595 The data values are mapped in the same way as described for the
8596 function <function>xmlelement</function> above.
8600 The parameter <parameter>nulls</parameter> determines whether null
8601 values should be included in the output. If true, null values in
8602 columns are represented as:
8604 <columnname xsi:nil="true
"/>
8606 where <literal>xsi</literal> is the XML namespace prefix for XML
8607 Schema Instance. An appropriate namespace declaration will be
8608 added to the result value. If false, columns containing null
8609 values are simply omitted from the output.
8613 The parameter <parameter>targetns</parameter> specifies the
8614 desired XML namespace of the result. If no particular namespace
8615 is wanted, an empty string should be passed.
8619 The following functions return XML Schema documents describing the
8620 mappings performed by the corresponding functions above:
8622 table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8623 query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8624 cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
8626 It is essential that the same parameters are passed in order to
8627 obtain matching XML data mappings and XML Schema documents.
8631 The following functions produce XML data mappings and the
8632 corresponding XML Schema in one document (or forest), linked
8633 together. They can be useful where self-contained and
8634 self-describing results are wanted:
8636 table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
8637 query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
8642 In addition, the following functions are available to produce
8643 analogous mappings of entire schemas or the entire current
8646 schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
8647 schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8648 schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
8650 database_to_xml(nulls boolean, tableforest boolean, targetns text)
8651 database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
8652 database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
8655 Note that these potentially produce a lot of data, which needs to
8656 be built up in memory. When requesting content mappings of large
8657 schemas or databases, it might be worthwhile to consider mapping the
8658 tables separately instead, possibly even through a cursor.
8662 The result of a schema content mapping looks like this:
8673 </schemaname>]]></screen>
8675 where the format of a table mapping depends on the
8676 <parameter>tableforest</parameter> parameter as explained above.
8680 The result of a database content mapping looks like this:
8695 </dbname>]]></screen>
8697 where the schema mapping is as above.
8701 As an example of using the output produced by these functions,
8702 <xref linkend="xslt-xml-html
"> shows an XSLT stylesheet that
8703 converts the output of
8704 <function>table_to_xml_and_xmlschema</function> to an HTML
8705 document containing a tabular rendition of the table data. In a
8706 similar manner, the results from these functions can be
8707 converted into other XML-based formats.
8710 <figure id="xslt-xml-html
">
8711 <title>XSLT stylesheet for converting SQL/XML output to HTML</title>
8712 <programlisting><![CDATA[
8713 <?xml version="1.0"?>
8714 <xsl:stylesheet version="1.0"
8715 xmlns:xsl="http://www.w3.org/
1999/XSL/Transform
"
8716 xmlns:xsd="http://www.w3.org/
2001/XMLSchema
"
8717 xmlns="http://www.w3.org/
1999/xhtml
"
8720 <xsl:output method="xml
"
8721 doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd
"
8722 doctype-public="-//W3C/DTD XHTML
1.0 Strict//EN
"
8725 <xsl:template match="/*
">
8726 <xsl:variable name="schema
" select="//xsd:schema
"/>
8727 <xsl:variable name="tabletypename
"
8728 select="$schema/xsd:element[@name=name(current())]/@type
"/>
8729 <xsl:variable name="rowtypename
"
8730 select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type
"/>
8734 <title><xsl:value-of select="name(current())
"/></title>
8739 <xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name
">
8740 <th><xsl:value-of select=".
"/></th>
8744 <xsl:for-each select="row
">
8746 <xsl:for-each select="*
">
8747 <td><xsl:value-of select=".
"/></td>
8757 ]]></programlisting>
8763 <sect1 id="functions-sequence
">
8764 <title>Sequence Manipulation Functions</title>
8767 <primary>sequence</primary>
8770 <primary>nextval</primary>
8773 <primary>currval</primary>
8776 <primary>lastval</primary>
8779 <primary>setval</primary>
8783 This section describes <productname>PostgreSQL</productname>'s
8784 functions for operating on <firstterm>sequence objects</firstterm>.
8785 Sequence objects (also called sequence generators or just
8786 sequences) are special single-row tables created with <xref
8787 linkend="sql-createsequence
" endterm="sql-createsequence-title
">.
8788 A sequence object is usually used to generate unique identifiers
8789 for rows of a table. The sequence functions, listed in <xref
8790 linkend="functions-sequence-table
">, provide simple, multiuser-safe
8791 methods for obtaining successive sequence values from sequence
8795 <table id="functions-sequence-table
">
8796 <title>Sequence Functions</title>
8799 <row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
8804 <entry><literal><function>currval</function>(<type>regclass</type>)</literal></entry>
8805 <entry><type>bigint</type></entry>
8806 <entry>Return value most recently obtained with
8807 <function>nextval</function> for specified sequence</entry>
8810 <entry><literal><function>lastval</function>()</literal></entry>
8811 <entry><type>bigint</type></entry>
8812 <entry>Return value most recently obtained with
8813 <function>nextval</function> for any sequence</entry>
8816 <entry><literal><function>nextval</function>(<type>regclass</type>)</literal></entry>
8817 <entry><type>bigint</type></entry>
8818 <entry>Advance sequence and return new value</entry>
8821 <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>)</literal></entry>
8822 <entry><type>bigint</type></entry>
8823 <entry>Set sequence's current value</entry>
8826 <entry><literal><function>setval</function>(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</literal></entry>
8827 <entry><type>bigint</type></entry>
8828 <entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
8835 The sequence to be operated on by a sequence function is specified by
8836 a <type>regclass</> argument, which is simply the OID of the sequence in the
8837 <structname>pg_class</> system catalog. You do not have to look up the
8838 OID by hand, however, since the <type>regclass</> data type's input
8839 converter will do the work for you. Just write the sequence name enclosed
8840 in single quotes so that it looks like a literal constant. For
8841 compatibility with the handling of ordinary
8842 <acronym>SQL</acronym> names, the string will be converted to lowercase
8843 unless it contains double quotes around the sequence name. Thus:
8845 nextval('foo') <lineannotation>operates on sequence <literal>foo</literal></>
8846 nextval('FOO') <lineannotation>operates on sequence <literal>foo</literal></>
8847 nextval('"Foo
"') <lineannotation>operates on sequence <literal>Foo</literal></>
8849 The sequence name can be schema-qualified if necessary:
8851 nextval('myschema.foo') <lineannotation>operates on <literal>myschema.foo</literal></>
8852 nextval('"myschema
".foo') <lineannotation>same as above</lineannotation>
8853 nextval('foo') <lineannotation>searches search path for <literal>foo</literal></>
8855 See <xref linkend="datatype-oid
"> for more information about
8861 Before <productname>PostgreSQL</productname> 8.1, the arguments of the
8862 sequence functions were of type <type>text</>, not <type>regclass</>, and
8863 the above-described conversion from a text string to an OID value would
8864 happen at run time during each call. For backwards compatibility, this
8865 facility still exists, but internally it is now handled as an implicit
8866 coercion from <type>text</> to <type>regclass</> before the function is
8871 When you write the argument of a sequence function as an unadorned
8872 literal string, it becomes a constant of type <type>regclass</>.
8873 Since this is really just an OID, it will track the originally
8874 identified sequence despite later renaming, schema reassignment,
8875 etc. This <quote>early binding</> behavior is usually desirable for
8876 sequence references in column defaults and views. But sometimes you might
8877 want <quote>late binding</> where the sequence reference is resolved
8878 at run time. To get late-binding behavior, force the constant to be
8879 stored as a <type>text</> constant instead of <type>regclass</>:
8881 nextval('foo'::text) <lineannotation><literal>foo</literal> is looked up at runtime</>
8883 Note that late binding was the only behavior supported in
8884 <productname>PostgreSQL</productname> releases before 8.1, so you
8885 might need to do this to preserve the semantics of old applications.
8889 Of course, the argument of a sequence function can be an expression
8890 as well as a constant. If it is a text expression then the implicit
8891 coercion will result in a run-time lookup.
8896 The available sequence functions are:
8900 <term><function>nextval</function></term>
8903 Advance the sequence object to its next value and return that
8904 value. This is done atomically: even if multiple sessions
8905 execute <function>nextval</function> concurrently, each will safely receive
8906 a distinct sequence value.
8912 <term><function>currval</function></term>
8915 Return the value most recently obtained by <function>nextval</function>
8916 for this sequence in the current session. (An error is
8917 reported if <function>nextval</function> has never been called for this
8918 sequence in this session.) Because this is returning
8919 a session-local value, it gives a predictable answer whether or not
8920 other sessions have executed <function>nextval</function> since the
8921 current session did.
8927 <term><function>lastval</function></term>
8930 Return the value most recently returned by
8931 <function>nextval</> in the current session. This function is
8932 identical to <function>currval</function>, except that instead
8933 of taking the sequence name as an argument it fetches the
8934 value of the last sequence used by <function>nextval</function>
8935 in the current session. It is an error to call
8936 <function>lastval</function> if <function>nextval</function>
8937 has not yet been called in the current session.
8943 <term><function>setval</function></term>
8946 Reset the sequence object's counter value. The two-parameter
8947 form sets the sequence's <literal>last_value</literal> field to the
8948 specified value and sets its <literal>is_called</literal> field to
8949 <literal>true</literal>, meaning that the next
8950 <function>nextval</function> will advance the sequence before
8951 returning a value. The value reported by <function>currval</> is
8952 also set to the specified value. In the three-parameter form,
8953 <literal>is_called</literal> can be set to either <literal>true</literal>
8954 or <literal>false</literal>. <literal>true</> has the same effect as
8955 the two-parameter form. If it is set to <literal>false</literal>, the
8956 next <function>nextval</function> will return exactly the specified
8957 value, and sequence advancement commences with the following
8958 <function>nextval</function>. Furthermore, the value reported by
8959 <function>currval</> is not changed in this case (this is a change
8960 from pre-8.3 behavior). For example,
8963 SELECT setval('foo', 42); <lineannotation>Next <function>nextval</> will return 43</lineannotation>
8964 SELECT setval('foo', 42, true); <lineannotation>Same as above</lineannotation>
8965 SELECT setval('foo', 42, false); <lineannotation>Next <function>nextval</> will return 42</lineannotation>
8968 The result returned by <function>setval</function> is just the value of its
8977 If a sequence object has been created with default parameters,
8978 successive <function>nextval</function> calls will return successive values
8979 beginning with 1. Other behaviors can be obtained by using
8980 special parameters in the <xref linkend="sql-createsequence
" endterm="sql-createsequence-title
"> command;
8981 see its command reference page for more information.
8986 To avoid blocking concurrent transactions that obtain numbers from the
8987 same sequence, a <function>nextval</function> operation is never rolled back;
8988 that is, once a value has been fetched it is considered used, even if the
8989 transaction that did the <function>nextval</function> later aborts. This means
8990 that aborted transactions might leave unused <quote>holes</quote> in the
8991 sequence of assigned values. <function>setval</function> operations are never
8992 rolled back, either.
8999 <sect1 id="functions-conditional
">
9000 <title>Conditional Expressions</title>
9003 <primary>CASE</primary>
9007 <primary>conditional expression</primary>
9011 This section describes the <acronym>SQL</acronym>-compliant conditional expressions
9012 available in <productname>PostgreSQL</productname>.
9017 If your needs go beyond the capabilities of these conditional
9018 expressions, you might want to consider writing a stored procedure
9019 in a more expressive programming language.
9024 <title><literal>CASE</></title>
9027 The <acronym>SQL</acronym> <token>CASE</token> expression is a
9028 generic conditional expression, similar to if/else statements in
9029 other programming languages:
9032 CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
9033 <optional>WHEN ...</optional>
9034 <optional>ELSE <replaceable>result</replaceable></optional>
9038 <token>CASE</token> clauses can be used wherever
9039 an expression is valid. Each <replaceable>condition</replaceable> is an
9040 expression that returns a <type>boolean</type> result. If the condition's
9041 result is true, the value of the <token>CASE</token> expression is the
9042 <replaceable>result</replaceable> that follows the condition, and the
9043 remainder of the <token>CASE</token> expression is not processed. If the
9044 condition's result is not true, any subsequent <token>WHEN</token> clauses
9045 are examined in the same manner. If no <token>WHEN</token>
9046 <replaceable>condition</replaceable> yields true, the value of the
9047 <token>CASE</> expression is the <replaceable>result</replaceable> of the
9048 <token>ELSE</token> clause. If the <token>ELSE</token> clause is
9049 omitted and no condition is true, the result is null.
9065 CASE WHEN a=1 THEN 'one'
9080 The data types of all the <replaceable>result</replaceable>
9081 expressions must be convertible to a single output type.
9082 See <xref linkend="typeconv-union-case
"> for more details.
9086 There is a <quote>simple</> form of <token>CASE</token> expression
9087 that is a variant of the general form above:
9090 CASE <replaceable>expression</replaceable>
9091 WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
9092 <optional>WHEN ...</optional>
9093 <optional>ELSE <replaceable>result</replaceable></optional>
9098 <replaceable>expression</replaceable> is computed, then compared to
9099 each of the <replaceable>value</replaceable> expressions in the
9100 <token>WHEN</token> clauses until one is found that is equal to it. If
9101 no match is found, the <replaceable>result</replaceable> of the
9102 <token>ELSE</token> clause (or a null value) is returned. This is similar
9103 to the <function>switch</function> statement in C.
9107 The example above can be written using the simple
9108 <token>CASE</token> syntax:
9111 CASE a WHEN 1 THEN 'one'
9126 A <token>CASE</token> expression does not evaluate any subexpressions
9127 that are not needed to determine the result. For example, this is a
9128 possible way of avoiding a division-by-zero failure:
9130 SELECT ... WHERE CASE WHEN x <> 0 THEN y/x > 1.5 ELSE false END;
9136 <title><literal>COALESCE</></title>
9139 <primary>COALESCE</primary>
9143 <primary>NVL</primary>
9147 <primary>IFNULL</primary>
9151 <function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9155 The <function>COALESCE</function> function returns the first of its
9156 arguments that is not null. Null is returned only if all arguments
9157 are null. It is often used to substitute a default value for
9158 null values when data is retrieved for display, for example:
9160 SELECT COALESCE(description, short_description, '(none)') ...
9165 Like a <token>CASE</token> expression, <function>COALESCE</function> only
9166 evaluates the arguments that are needed to determine the result;
9167 that is, arguments to the right of the first non-null argument are
9168 not evaluated. This SQL-standard function provides capabilities similar
9169 to <function>NVL</> and <function>IFNULL</>, which are used in some other
9175 <title><literal>NULLIF</></title>
9178 <primary>NULLIF</primary>
9182 <function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
9186 The <function>NULLIF</function> function returns a null value if
9187 <replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
9188 otherwise it returns <replaceable>value1</replaceable>.
9189 This can be used to perform the inverse operation of the
9190 <function>COALESCE</function> example given above:
9192 SELECT NULLIF(value, '(none)') ...
9196 If <replaceable>value1</replaceable> is <literal>(none)</>, return a null,
9197 otherwise return <replaceable>value1</replaceable>.
9203 <title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
9206 <primary>GREATEST</primary>
9209 <primary>LEAST</primary>
9213 <function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9216 <function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
9220 The <function>GREATEST</> and <function>LEAST</> functions select the
9221 largest or smallest value from a list of any number of expressions.
9222 The expressions must all be convertible to a common data type, which
9223 will be the type of the result
9224 (see <xref linkend="typeconv-union-case
"> for details). NULL values
9225 in the list are ignored. The result will be NULL only if all the
9226 expressions evaluate to NULL.
9230 Note that <function>GREATEST</> and <function>LEAST</> are not in
9231 the SQL standard, but are a common extension. Some other databases
9232 make them return NULL if any argument is NULL, rather than only when
9238 <sect1 id="functions-array
">
9239 <title>Array Functions and Operators</title>
9242 <xref linkend="array-operators-table
"> shows the operators
9243 available for array types.
9246 <table id="array-operators-table
">
9247 <title>Array Operators</title>
9251 <entry>Operator</entry>
9252 <entry>Description</entry>
9253 <entry>Example</entry>
9254 <entry>Result</entry>
9259 <entry> <literal>=</literal> </entry>
9260 <entry>equal</entry>
9261 <entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
9262 <entry><literal>t</literal></entry>
9266 <entry> <literal><></literal> </entry>
9267 <entry>not equal</entry>
9268 <entry><literal>ARRAY[1,2,3] <> ARRAY[1,2,4]</literal></entry>
9269 <entry><literal>t</literal></entry>
9273 <entry> <literal><</literal> </entry>
9274 <entry>less than</entry>
9275 <entry><literal>ARRAY[1,2,3] < ARRAY[1,2,4]</literal></entry>
9276 <entry><literal>t</literal></entry>
9280 <entry> <literal>></literal> </entry>
9281 <entry>greater than</entry>
9282 <entry><literal>ARRAY[1,4,3] > ARRAY[1,2,4]</literal></entry>
9283 <entry><literal>t</literal></entry>
9287 <entry> <literal><=</literal> </entry>
9288 <entry>less than or equal</entry>
9289 <entry><literal>ARRAY[1,2,3] <= ARRAY[1,2,3]</literal></entry>
9290 <entry><literal>t</literal></entry>
9294 <entry> <literal>>=</literal> </entry>
9295 <entry>greater than or equal</entry>
9296 <entry><literal>ARRAY[1,4,3] >= ARRAY[1,4,3]</literal></entry>
9297 <entry><literal>t</literal></entry>
9301 <entry> <literal>@></literal> </entry>
9302 <entry>contains</entry>
9303 <entry><literal>ARRAY[1,4,3] @> ARRAY[3,1]</literal></entry>
9304 <entry><literal>t</literal></entry>
9308 <entry> <literal><@</literal> </entry>
9309 <entry>is contained by</entry>
9310 <entry><literal>ARRAY[2,7] <@ ARRAY[1,7,4,2,6]</literal></entry>
9311 <entry><literal>t</literal></entry>
9315 <entry> <literal>&&</literal> </entry>
9316 <entry>overlap (have elements in common)</entry>
9317 <entry><literal>ARRAY[1,4,3] && ARRAY[2,1]</literal></entry>
9318 <entry><literal>t</literal></entry>
9322 <entry> <literal>||</literal> </entry>
9323 <entry>array-to-array concatenation</entry>
9324 <entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
9325 <entry><literal>{1,2,3,4,5,6}</literal></entry>
9329 <entry> <literal>||</literal> </entry>
9330 <entry>array-to-array concatenation</entry>
9331 <entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
9332 <entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
9336 <entry> <literal>||</literal> </entry>
9337 <entry>element-to-array concatenation</entry>
9338 <entry><literal>3 || ARRAY[4,5,6]</literal></entry>
9339 <entry><literal>{3,4,5,6}</literal></entry>
9343 <entry> <literal>||</literal> </entry>
9344 <entry>array-to-element concatenation</entry>
9345 <entry><literal>ARRAY[4,5,6] || 7</literal></entry>
9346 <entry><literal>{4,5,6,7}</literal></entry>
9353 Array comparisons compare the array contents element-by-element,
9354 using the default B-Tree comparison function for the element data type.
9355 In multidimensional arrays the elements are visited in row-major order
9356 (last subscript varies most rapidly).
9357 If the contents of two arrays are equal but the dimensionality is
9358 different, the first difference in the dimensionality information
9359 determines the sort order. (This is a change from versions of
9360 <productname>PostgreSQL</> prior to 8.2: older versions would claim
9361 that two arrays with the same contents were equal, even if the
9362 number of dimensions or subscript ranges were different.)
9366 See <xref linkend="arrays
"> for more details about array operator
9371 <xref linkend="array-functions-table
"> shows the functions
9372 available for use with array types. See <xref linkend="arrays
">
9373 for more information and examples of the use of these functions.
9377 <primary>array_append</primary>
9380 <primary>array_cat</primary>
9383 <primary>array_ndims</primary>
9386 <primary>array_dims</primary>
9389 <primary>array_fill</primary>
9392 <primary>array_length</primary>
9395 <primary>array_lower</primary>
9398 <primary>array_prepend</primary>
9401 <primary>array_to_string</primary>
9404 <primary>array_upper</primary>
9407 <primary>string_to_array</primary>
9410 <primary>unnest</primary>
9413 <table id="array-functions-table
">
9414 <title>Array Functions</title>
9418 <entry>Function</entry>
9419 <entry>Return Type</entry>
9420 <entry>Description</entry>
9421 <entry>Example</entry>
9422 <entry>Result</entry>
9429 <function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
9432 <entry><type>anyarray</type></entry>
9433 <entry>append an element to the end of an array</entry>
9434 <entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
9435 <entry><literal>{1,2,3}</literal></entry>
9440 <function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
9443 <entry><type>anyarray</type></entry>
9444 <entry>concatenate two arrays</entry>
9445 <entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
9446 <entry><literal>{1,2,3,4,5}</literal></entry>
9451 <function>array_ndims</function>(<type>anyarray</type>)
9454 <entry><type>int</type></entry>
9455 <entry>returns the number of dimensions of the array</entry>
9456 <entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9457 <entry><literal>2</literal></entry>
9462 <function>array_dims</function>(<type>anyarray</type>)
9465 <entry><type>text</type></entry>
9466 <entry>returns a text representation of array's dimensions</entry>
9467 <entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
9468 <entry><literal>[1:2][1:3]</literal></entry>
9473 <function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
9474 <optional>, <type>int[]</type></optional>)
9477 <entry><type>anyarray</type></entry>
9478 <entry>returns an array initialized with supplied value and
9479 dimensions, optionally with lower bounds other than 1</entry>
9480 <entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
9481 <entry><literal>[2:4]={7,7,7}</literal></entry>
9486 <function>array_length</function>(<type>anyarray</type>, <type>int</type>)
9489 <entry><type>int</type></entry>
9490 <entry>returns the length of the requested array dimension</entry>
9491 <entry><literal>array_length(array[1,2,3], 1)</literal></entry>
9492 <entry><literal>3</literal></entry>
9497 <function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
9500 <entry><type>int</type></entry>
9501 <entry>returns lower bound of the requested array dimension</entry>
9502 <entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
9503 <entry><literal>0</literal></entry>
9508 <function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
9511 <entry><type>anyarray</type></entry>
9512 <entry>append an element to the beginning of an array</entry>
9513 <entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
9514 <entry><literal>{1,2,3}</literal></entry>
9519 <function>array_to_string</function>(<type>anyarray</type>, <type>text</type>)
9522 <entry><type>text</type></entry>
9523 <entry>concatenates array elements using supplied delimiter</entry>
9524 <entry><literal>array_to_string(ARRAY[1, 2, 3], '~^~')</literal></entry>
9525 <entry><literal>1~^~2~^~3</literal></entry>
9530 <function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
9533 <entry><type>int</type></entry>
9534 <entry>returns upper bound of the requested array dimension</entry>
9535 <entry><literal>array_upper(ARRAY[1,2,3,4], 1)</literal></entry>
9536 <entry><literal>4</literal></entry>
9541 <function>string_to_array</function>(<type>text</type>, <type>text</type>)
9544 <entry><type>text[]</type></entry>
9545 <entry>splits string into array elements using supplied delimiter</entry>
9546 <entry><literal>string_to_array('xx~^~yy~^~zz', '~^~')</literal></entry>
9547 <entry><literal>{xx,yy,zz}</literal></entry>
9552 <function>unnest</function>(<type>anyarray</type>)
9555 <entry><type>setof anyelement</type></entry>
9556 <entry>expand an array to a set of rows</entry>
9557 <entry><literal>unnest(ARRAY[1,2])</literal></entry>
9558 <entry><literal>1</literal><para><literal>2</literal></para> (2 rows)</entry>
9565 See also <xref linkend="functions-aggregate
"> about the aggregate
9566 function <function>array_agg</function> for use with arrays.
9570 <sect1 id="functions-aggregate
">
9571 <title>Aggregate Functions</title>
9573 <indexterm zone="functions-aggregate
">
9574 <primary>aggregate function</primary>
9575 <secondary>built-in</secondary>
9579 <firstterm>Aggregate functions</firstterm> compute a single result
9580 from a set of input values. The built-in aggregate functions
9582 <xref linkend="functions-aggregate-table
"> and
9583 <xref linkend="functions-aggregate-statistics-table
">.
9584 The special syntax considerations for aggregate
9585 functions are explained in <xref linkend="syntax-aggregates
">.
9586 Consult <xref linkend="tutorial-agg
"> for additional introductory
9590 <table id="functions-aggregate-table
">
9591 <title>General-Purpose Aggregate Functions</title>
9596 <entry>Function</entry>
9597 <entry>Argument Type</entry>
9598 <entry>Return Type</entry>
9599 <entry>Description</entry>
9607 <primary>array_agg</primary>
9609 <function>array_agg(<replaceable class="parameter
">expression</replaceable>)</function>
9615 array of the argument type
9617 <entry>input values concatenated into an array</entry>
9623 <primary>average</primary>
9625 <function>avg(<replaceable class="parameter
">expression</replaceable>)</function>
9628 <type>smallint</type>, <type>int</type>,
9629 <type>bigint</type>, <type>real</type>, <type>double
9630 precision</type>, <type>numeric</type>, or <type>interval</type>
9633 <type>numeric</type> for any integer-type argument,
9634 <type>double precision</type> for a floating-point argument,
9635 otherwise the same as the argument data type
9637 <entry>the average (arithmetic mean) of all input values</entry>
9643 <primary>bit_and</primary>
9645 <function>bit_and(<replaceable class="parameter
">expression</replaceable>)</function>
9648 <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9652 same as argument data type
9654 <entry>the bitwise AND of all non-null input values, or null if none</entry>
9660 <primary>bit_or</primary>
9662 <function>bit_or(<replaceable class="parameter
">expression</replaceable>)</function>
9665 <type>smallint</type>, <type>int</type>, <type>bigint</type>, or
9669 same as argument data type
9671 <entry>the bitwise OR of all non-null input values, or null if none</entry>
9677 <primary>bool_and</primary>
9679 <function>bool_and(<replaceable class="parameter
">expression</replaceable>)</function>
9687 <entry>true if all input values are true, otherwise false</entry>
9693 <primary>bool_or</primary>
9695 <function>bool_or(<replaceable class="parameter
">expression</replaceable>)</function>
9703 <entry>true if at least one input value is true, otherwise false</entry>
9707 <entry><function>count(*)</function></entry>
9709 <entry><type>bigint</type></entry>
9710 <entry>number of input rows</entry>
9714 <entry><function>count(<replaceable class="parameter
">expression</replaceable>)</function></entry>
9716 <entry><type>bigint</type></entry>
9718 number of input rows for which the value of <replaceable
9719 class="parameter
">expression</replaceable> is not null
9726 <primary>every</primary>
9728 <function>every(<replaceable class="parameter
">expression</replaceable>)</function>
9736 <entry>equivalent to <function>bool_and</function></entry>
9740 <entry><function>max(<replaceable class="parameter
">expression</replaceable>)</function></entry>
9741 <entry>any array, numeric, string, or date/time type</entry>
9742 <entry>same as argument type</entry>
9744 maximum value of <replaceable
9745 class="parameter
">expression</replaceable> across all input
9751 <entry><function>min(<replaceable class="parameter
">expression</replaceable>)</function></entry>
9752 <entry>any array, numeric, string, or date/time type</entry>
9753 <entry>same as argument type</entry>
9755 minimum value of <replaceable
9756 class="parameter
">expression</replaceable> across all input
9762 <entry><function>sum(<replaceable class="parameter
">expression</replaceable>)</function></entry>
9764 <type>smallint</type>, <type>int</type>,
9765 <type>bigint</type>, <type>real</type>, <type>double
9766 precision</type>, <type>numeric</type>, or
9767 <type>interval</type>
9770 <type>bigint</type> for <type>smallint</type> or
9771 <type>int</type> arguments, <type>numeric</type> for
9772 <type>bigint</type> arguments, <type>double precision</type>
9773 for floating-point arguments, otherwise the same as the
9776 <entry>sum of <replaceable class="parameter
">expression</replaceable> across all input values</entry>
9782 <primary>xmlagg</primary>
9784 <function>xmlagg(<replaceable class="parameter
">expression</replaceable>)</function>
9792 <entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg
">)</entry>
9799 It should be noted that except for <function>count</function>,
9800 these functions return a null value when no rows are selected. In
9801 particular, <function>sum</function> of no rows returns null, not
9802 zero as one might expect, and <function>array_agg</function>
9803 returns null rather than an empty array when there are no input
9804 rows. The <function>coalesce</function> function can be used to
9805 substitute zero or an empty array for null when necessary.
9810 <primary>ANY</primary>
9813 <primary>SOME</primary>
9816 Boolean aggregates <function>bool_and</function> and
9817 <function>bool_or</function> correspond to standard SQL aggregates
9818 <function>every</function> and <function>any</function> or
9819 <function>some</function>.
9820 As for <function>any</function> and <function>some</function>,
9821 it seems that there is an ambiguity built into the standard syntax:
9823 SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
9825 Here <function>ANY</function> can be considered either as introducing
9826 a subquery, or as being an aggregate function, if the sub-select
9827 returns one row with a boolean value.
9828 Thus the standard name cannot be given to these aggregates.
9834 Users accustomed to working with other SQL database management
9835 systems might be disappointed by the performance of the
9836 <function>count</function> aggregate when it is applied to the
9837 entire table. A query like:
9839 SELECT count(*) FROM sometable;
9841 will be executed by <productname>PostgreSQL</productname> using a
9842 sequential scan of the entire table.
9847 The aggregate functions <function>array_agg</function>
9848 and <function>xmlagg</function>, as well as similar user-defined
9849 aggregate functions, produce meaningfully different result values
9850 depending on the order of the input values. In the current
9851 implementation, the order of the input is in principle unspecified.
9852 Supplying the input values from a sorted subquery
9853 will usually work, however. For example:
9856 SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
9859 But this syntax is not allowed in the SQL standard, and is
9860 not portable to other database systems. A future version of
9861 <productname>PostgreSQL</> might provide an additional feature to control
9862 the order in a better-defined way (<literal>xmlagg(expr ORDER BY expr, expr,
9867 <xref linkend="functions-aggregate-statistics-table
"> shows
9868 aggregate functions typically used in statistical analysis.
9869 (These are separated out merely to avoid cluttering the listing
9870 of more-commonly-used aggregates.) Where the description mentions
9871 <replaceable class="parameter
">N</replaceable>, it means the
9872 number of input rows for which all the input expressions are non-null.
9873 In all cases, null is returned if the computation is meaningless,
9874 for example when <replaceable class="parameter
">N</replaceable> is zero.
9878 <primary>statistics</primary>
9881 <primary>linear regression</primary>
9884 <table id="functions-aggregate-statistics-table
">
9885 <title>Aggregate Functions for Statistics</title>
9890 <entry>Function</entry>
9891 <entry>Argument Type</entry>
9892 <entry>Return Type</entry>
9893 <entry>Description</entry>
9902 <primary>correlation</primary>
9904 <function>corr(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
9907 <type>double precision</type>
9910 <type>double precision</type>
9912 <entry>correlation coefficient</entry>
9918 <primary>covariance</primary>
9919 <secondary>population</secondary>
9921 <function>covar_pop(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
9924 <type>double precision</type>
9927 <type>double precision</type>
9929 <entry>population covariance</entry>
9935 <primary>covariance</primary>
9936 <secondary>sample</secondary>
9938 <function>covar_samp(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
9941 <type>double precision</type>
9944 <type>double precision</type>
9946 <entry>sample covariance</entry>
9951 <function>regr_avgx(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
9954 <type>double precision</type>
9957 <type>double precision</type>
9959 <entry>average of the independent variable
9960 (<literal>sum(<replaceable class="parameter
">X</replaceable>)/<replaceable class="parameter
">N</replaceable></literal>)</entry>
9965 <function>regr_avgy(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
9968 <type>double precision</type>
9971 <type>double precision</type>
9973 <entry>average of the dependent variable
9974 (<literal>sum(<replaceable class="parameter
">Y</replaceable>)/<replaceable class="parameter
">N</replaceable></literal>)</entry>
9979 <function>regr_count(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
9982 <type>double precision</type>
9987 <entry>number of input rows in which both expressions are nonnull</entry>
9993 <primary>regression intercept</primary>
9995 <function>regr_intercept(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
9998 <type>double precision</type>
10001 <type>double precision</type>
10003 <entry>y-intercept of the least-squares-fit linear equation
10004 determined by the (<replaceable
10005 class="parameter
">X</replaceable>, <replaceable
10006 class="parameter
">Y</replaceable>) pairs</entry>
10011 <function>regr_r2(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
10014 <type>double precision</type>
10017 <type>double precision</type>
10019 <entry>square of the correlation coefficient</entry>
10025 <primary>regression slope</primary>
10027 <function>regr_slope(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
10030 <type>double precision</type>
10033 <type>double precision</type>
10035 <entry>slope of the least-squares-fit linear equation determined
10036 by the (<replaceable class="parameter
">X</replaceable>,
10037 <replaceable class="parameter
">Y</replaceable>) pairs</entry>
10042 <function>regr_sxx(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
10045 <type>double precision</type>
10048 <type>double precision</type>
10050 <entry><literal>sum(<replaceable
10051 class="parameter
">X</replaceable>^2) - sum(<replaceable
10052 class="parameter
">X</replaceable>)^2/<replaceable
10053 class="parameter
">N</replaceable></literal> (<quote>sum of
10054 squares</quote> of the independent variable)</entry>
10059 <function>regr_sxy(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
10062 <type>double precision</type>
10065 <type>double precision</type>
10067 <entry><literal>sum(<replaceable
10068 class="parameter
">X</replaceable>*<replaceable
10069 class="parameter
">Y</replaceable>) - sum(<replaceable
10070 class="parameter
">X</replaceable>) * sum(<replaceable
10071 class="parameter
">Y</replaceable>)/<replaceable
10072 class="parameter
">N</replaceable></literal> (<quote>sum of
10073 products</quote> of independent times dependent
10079 <function>regr_syy(<replaceable class="parameter
">Y</replaceable>, <replaceable class="parameter
">X</replaceable>)</function>
10082 <type>double precision</type>
10085 <type>double precision</type>
10087 <entry><literal>sum(<replaceable
10088 class="parameter
">Y</replaceable>^2) - sum(<replaceable
10089 class="parameter
">Y</replaceable>)^2/<replaceable
10090 class="parameter
">N</replaceable></literal> (<quote>sum of
10091 squares</quote> of the dependent variable)</entry>
10097 <primary>standard deviation</primary>
10099 <function>stddev(<replaceable class="parameter
">expression</replaceable>)</function>
10102 <type>smallint</type>, <type>int</type>,
10103 <type>bigint</type>, <type>real</type>, <type>double
10104 precision</type>, or <type>numeric</type>
10107 <type>double precision</type> for floating-point arguments,
10108 otherwise <type>numeric</type>
10110 <entry>historical alias for <function>stddev_samp</function></entry>
10116 <primary>standard deviation</primary>
10117 <secondary>population</secondary>
10119 <function>stddev_pop(<replaceable class="parameter
">expression</replaceable>)</function>
10122 <type>smallint</type>, <type>int</type>,
10123 <type>bigint</type>, <type>real</type>, <type>double
10124 precision</type>, or <type>numeric</type>
10127 <type>double precision</type> for floating-point arguments,
10128 otherwise <type>numeric</type>
10130 <entry>population standard deviation of the input values</entry>
10136 <primary>standard deviation</primary>
10137 <secondary>sample</secondary>
10139 <function>stddev_samp(<replaceable class="parameter
">expression</replaceable>)</function>
10142 <type>smallint</type>, <type>int</type>,
10143 <type>bigint</type>, <type>real</type>, <type>double
10144 precision</type>, or <type>numeric</type>
10147 <type>double precision</type> for floating-point arguments,
10148 otherwise <type>numeric</type>
10150 <entry>sample standard deviation of the input values</entry>
10156 <primary>variance</primary>
10158 <function>variance</function>(<replaceable class="parameter
">expression</replaceable>)
10161 <type>smallint</type>, <type>int</type>,
10162 <type>bigint</type>, <type>real</type>, <type>double
10163 precision</type>, or <type>numeric</type>
10166 <type>double precision</type> for floating-point arguments,
10167 otherwise <type>numeric</type>
10169 <entry>historical alias for <function>var_samp</function></entry>
10175 <primary>variance</primary>
10176 <secondary>population</secondary>
10178 <function>var_pop</function>(<replaceable class="parameter
">expression</replaceable>)
10181 <type>smallint</type>, <type>int</type>,
10182 <type>bigint</type>, <type>real</type>, <type>double
10183 precision</type>, or <type>numeric</type>
10186 <type>double precision</type> for floating-point arguments,
10187 otherwise <type>numeric</type>
10189 <entry>population variance of the input values (square of the population standard deviation)</entry>
10195 <primary>variance</primary>
10196 <secondary>sample</secondary>
10198 <function>var_samp</function>(<replaceable class="parameter
">expression</replaceable>)
10201 <type>smallint</type>, <type>int</type>,
10202 <type>bigint</type>, <type>real</type>, <type>double
10203 precision</type>, or <type>numeric</type>
10206 <type>double precision</type> for floating-point arguments,
10207 otherwise <type>numeric</type>
10209 <entry>sample variance of the input values (square of the sample standard deviation)</entry>
10217 <sect1 id="functions-window
">
10218 <title>Window Functions</title>
10220 <indexterm zone="functions-window
">
10221 <primary>window function</primary>
10222 <secondary>built-in</secondary>
10226 <firstterm>Window functions</firstterm> provide the ability to perform
10227 calculations across sets of rows that are related to the current query
10228 row. See <xref linkend="tutorial-window
"> for an introduction to this
10233 The built-in window functions are listed in
10234 <xref linkend="functions-window-table
">. Note that these functions
10235 <emphasis>must</> be invoked using window function syntax; that is an
10236 <literal>OVER</> clause is required.
10240 In addition to these functions, any built-in or user-defined aggregate
10241 function can be used as a window function (see
10242 <xref linkend="functions-aggregate
"> for a list of the built-in aggregates).
10243 Aggregate functions act as window functions only when an <literal>OVER</>
10244 clause follows the call; otherwise they act as regular aggregates.
10247 <table id="functions-window-table
">
10248 <title>General-Purpose Window Functions</title>
10253 <entry>Function</entry>
10254 <entry>Return Type</entry>
10255 <entry>Description</entry>
10263 <primary>row_number</primary>
10265 <function>row_number()</function>
10268 <type>bigint</type>
10270 <entry>number of the current row within its partition, counting from 1</entry>
10276 <primary>rank</primary>
10278 <function>rank()</function>
10281 <type>bigint</type>
10283 <entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
10289 <primary>dense_rank</primary>
10291 <function>dense_rank()</function>
10294 <type>bigint</type>
10296 <entry>rank of the current row without gaps; this function counts peer groups</entry>
10302 <primary>percent_rank</primary>
10304 <function>percent_rank()</function>
10307 <type>double precision</type>
10309 <entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
10315 <primary>cume_dist</primary>
10317 <function>cume_dist()</function>
10320 <type>double precision</type>
10322 <entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
10328 <primary>ntile</primary>
10330 <function>ntile(<replaceable class="parameter
">num_buckets</replaceable> <type>integer</>)</function>
10333 <type>integer</type>
10335 <entry>integer ranging from 1 to the argument value, dividing the
10336 partition as equally as possible</entry>
10342 <primary>lag</primary>
10345 lag(<replaceable class="parameter
">value</replaceable> <type>any</>
10346 [, <replaceable class="parameter
">offset</replaceable> <type>integer</>
10347 [, <replaceable class="parameter
">default</replaceable> <type>any</> ]])
10351 <type>same type as <replaceable class="parameter
">value</replaceable></type>
10354 returns <replaceable class="parameter
">value</replaceable> evaluated at
10355 the row that is <replaceable class="parameter
">offset</replaceable>
10356 rows before the current row within the partition; if there is no such
10357 row, instead return <replaceable class="parameter
">default</replaceable>.
10358 Both <replaceable class="parameter
">offset</replaceable> and
10359 <replaceable class="parameter
">default</replaceable> are evaluated
10360 with respect to the current row. If omitted,
10361 <replaceable class="parameter
">offset</replaceable> defaults to 1 and
10362 <replaceable class="parameter
">default</replaceable> to null
10369 <primary>lead</primary>
10372 lead(<replaceable class="parameter
">value</replaceable> <type>any</>
10373 [, <replaceable class="parameter
">offset</replaceable> <type>integer</>
10374 [, <replaceable class="parameter
">default</replaceable> <type>any</> ]])
10378 <type>same type as <replaceable class="parameter
">value</replaceable></type>
10381 returns <replaceable class="parameter
">value</replaceable> evaluated at
10382 the row that is <replaceable class="parameter
">offset</replaceable>
10383 rows after the current row within the partition; if there is no such
10384 row, instead return <replaceable class="parameter
">default</replaceable>.
10385 Both <replaceable class="parameter
">offset</replaceable> and
10386 <replaceable class="parameter
">default</replaceable> are evaluated
10387 with respect to the current row. If omitted,
10388 <replaceable class="parameter
">offset</replaceable> defaults to 1 and
10389 <replaceable class="parameter
">default</replaceable> to null
10396 <primary>first_value</primary>
10398 <function>first_value(<replaceable class="parameter
">value</replaceable> <type>any</>)</function>
10401 <type>same type as <replaceable class="parameter
">value</replaceable></type>
10404 returns <replaceable class="parameter
">value</replaceable> evaluated
10405 at the row that is the first row of the window frame
10412 <primary>last_value</primary>
10414 <function>last_value(<replaceable class="parameter
">value</replaceable> <type>any</>)</function>
10417 <type>same type as <replaceable class="parameter
">value</replaceable></type>
10420 returns <replaceable class="parameter
">value</replaceable> evaluated
10421 at the row that is the last row of the window frame
10428 <primary>nth_value</primary>
10431 nth_value(<replaceable class="parameter
">value</replaceable> <type>any</>, <replaceable class="parameter
">nth</replaceable> <type>integer</>)
10435 <type>same type as <replaceable class="parameter
">value</replaceable></type>
10438 returns <replaceable class="parameter
">value</replaceable> evaluated
10439 at the row that is the <replaceable class="parameter
">nth</replaceable>
10440 row of the window frame (counting from 1); null if no such row
10448 All of the functions listed in
10449 <xref linkend="functions-window-table
"> depend on the sort ordering
10450 specified by the <literal>ORDER BY</> clause of the associated window
10451 definition. Rows that are not distinct in the <literal>ORDER BY</>
10452 ordering are said to be <firstterm>peers</>; the four ranking functions
10453 are defined so that they give the same answer for any two peer rows.
10457 Note that <function>first_value</>, <function>last_value</>, and
10458 <function>nth_value</> consider only the rows within the <quote>window
10459 frame</>, which by default contains the rows from the start of the
10460 partition through the last peer of the current row. This is
10461 likely to give unhelpful results for <function>nth_value</> and
10462 particularly <function>last_value</>. You can redefine the frame as
10463 being the whole partition by adding <literal>ROWS BETWEEN UNBOUNDED
10464 PRECEDING AND UNBOUNDED FOLLOWING</> to the <literal>OVER</> clause.
10465 See <xref linkend="syntax-window-functions
"> for more information.
10469 When an aggregate function is used as a window function, it aggregates
10470 over the rows within the current row's window frame. To obtain
10471 aggregation over the whole partition, omit <literal>ORDER BY</> or use
10472 <literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
10473 An aggregate used with <literal>ORDER BY</> and the default window frame
10474 definition produces a <quote>running sum</> type of behavior, which may or
10475 may not be what's wanted.
10480 The SQL standard defines a <literal>RESPECT NULLS</> or
10481 <literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
10482 <function>first_value</>, <function>last_value</>, and
10483 <function>nth_value</>. This is not implemented in
10484 <productname>PostgreSQL</productname>: the behavior is always the
10485 same as the standard's default, namely <literal>RESPECT NULLS</>.
10486 Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
10487 option for <function>nth_value</> is not implemented: only the
10488 default <literal>FROM FIRST</> behavior is supported. (You can achieve
10489 the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
10496 <sect1 id="functions-subquery
">
10497 <title>Subquery Expressions</title>
10500 <primary>EXISTS</primary>
10504 <primary>IN</primary>
10508 <primary>NOT IN</primary>
10512 <primary>ANY</primary>
10516 <primary>ALL</primary>
10520 <primary>SOME</primary>
10524 <primary>subquery</primary>
10528 This section describes the <acronym>SQL</acronym>-compliant subquery
10529 expressions available in <productname>PostgreSQL</productname>.
10530 All of the expression forms documented in this section return
10531 Boolean (true/false) results.
10535 <title><literal>EXISTS</literal></title>
10538 EXISTS (<replaceable>subquery</replaceable>)
10542 The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
10543 or <firstterm>subquery</firstterm>. The
10544 subquery is evaluated to determine whether it returns any rows.
10545 If it returns at least one row, the result of <token>EXISTS</token> is
10546 <quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
10547 is <quote>false</>.
10551 The subquery can refer to variables from the surrounding query,
10552 which will act as constants during any one evaluation of the subquery.
10556 The subquery will generally only be executed long enough to determine
10557 whether at least one row is returned, not all the way to completion.
10558 It is unwise to write a subquery that has side effects (such as
10559 calling sequence functions); whether the side effects occur
10560 might be unpredictable.
10564 Since the result depends only on whether any rows are returned,
10565 and not on the contents of those rows, the output list of the
10566 subquery is normally unimportant. A common coding convention is
10567 to write all <literal>EXISTS</> tests in the form
10568 <literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
10569 this rule however, such as subqueries that use <token>INTERSECT</token>.
10573 This simple example is like an inner join on <literal>col2</>, but
10574 it produces at most one output row for each <literal>tab1</> row,
10575 even if there are several matching <literal>tab2</> rows:
10579 WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
10585 <title><literal>IN</literal></title>
10588 <replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
10592 The right-hand side is a parenthesized
10593 subquery, which must return exactly one column. The left-hand expression
10594 is evaluated and compared to each row of the subquery result.
10595 The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10596 The result is <quote>false</> if no equal row is found (including the
10597 case where the subquery returns no rows).
10601 Note that if the left-hand expression yields null, or if there are
10602 no equal right-hand values and at least one right-hand row yields
10603 null, the result of the <token>IN</token> construct will be null, not false.
10604 This is in accordance with SQL's normal rules for Boolean combinations
10609 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10610 be evaluated completely.
10614 <replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
10618 The left-hand side of this form of <token>IN</token> is a row constructor,
10619 as described in <xref linkend="sql-syntax-row-constructors
">.
10620 The right-hand side is a parenthesized
10621 subquery, which must return exactly as many columns as there are
10622 expressions in the left-hand row. The left-hand expressions are
10623 evaluated and compared row-wise to each row of the subquery result.
10624 The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
10625 The result is <quote>false</> if no equal row is found (including the
10626 case where the subquery returns no rows).
10630 As usual, null values in the rows are combined per
10631 the normal rules of SQL Boolean expressions. Two rows are considered
10632 equal if all their corresponding members are non-null and equal; the rows
10633 are unequal if any corresponding members are non-null and unequal;
10634 otherwise the result of that row comparison is unknown (null).
10635 If all the per-row results are either unequal or null, with at least one
10636 null, then the result of <token>IN</token> is null.
10641 <title><literal>NOT IN</literal></title>
10644 <replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10648 The right-hand side is a parenthesized
10649 subquery, which must return exactly one column. The left-hand expression
10650 is evaluated and compared to each row of the subquery result.
10651 The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10652 are found (including the case where the subquery returns no rows).
10653 The result is <quote>false</> if any equal row is found.
10657 Note that if the left-hand expression yields null, or if there are
10658 no equal right-hand values and at least one right-hand row yields
10659 null, the result of the <token>NOT IN</token> construct will be null, not true.
10660 This is in accordance with SQL's normal rules for Boolean combinations
10665 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10666 be evaluated completely.
10670 <replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
10674 The left-hand side of this form of <token>NOT IN</token> is a row constructor,
10675 as described in <xref linkend="sql-syntax-row-constructors
">.
10676 The right-hand side is a parenthesized
10677 subquery, which must return exactly as many columns as there are
10678 expressions in the left-hand row. The left-hand expressions are
10679 evaluated and compared row-wise to each row of the subquery result.
10680 The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
10681 are found (including the case where the subquery returns no rows).
10682 The result is <quote>false</> if any equal row is found.
10686 As usual, null values in the rows are combined per
10687 the normal rules of SQL Boolean expressions. Two rows are considered
10688 equal if all their corresponding members are non-null and equal; the rows
10689 are unequal if any corresponding members are non-null and unequal;
10690 otherwise the result of that row comparison is unknown (null).
10691 If all the per-row results are either unequal or null, with at least one
10692 null, then the result of <token>NOT IN</token> is null.
10697 <title><literal>ANY</literal>/<literal>SOME</literal></title>
10700 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
10701 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
10705 The right-hand side is a parenthesized
10706 subquery, which must return exactly one column. The left-hand expression
10707 is evaluated and compared to each row of the subquery result using the
10708 given <replaceable>operator</replaceable>, which must yield a Boolean
10710 The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10711 The result is <quote>false</> if no true result is found (including the
10712 case where the subquery returns no rows).
10716 <token>SOME</token> is a synonym for <token>ANY</token>.
10717 <token>IN</token> is equivalent to <literal>= ANY</literal>.
10721 Note that if there are no successes and at least one right-hand row yields
10722 null for the operator's result, the result of the <token>ANY</token> construct
10723 will be null, not false.
10724 This is in accordance with SQL's normal rules for Boolean combinations
10729 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10730 be evaluated completely.
10734 <replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
10735 <replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
10739 The left-hand side of this form of <token>ANY</token> is a row constructor,
10740 as described in <xref linkend="sql-syntax-row-constructors
">.
10741 The right-hand side is a parenthesized
10742 subquery, which must return exactly as many columns as there are
10743 expressions in the left-hand row. The left-hand expressions are
10744 evaluated and compared row-wise to each row of the subquery result,
10745 using the given <replaceable>operator</replaceable>.
10746 The result of <token>ANY</token> is <quote>true</> if the comparison
10747 returns true for any subquery row.
10748 The result is <quote>false</> if the comparison returns false for every
10749 subquery row (including the case where the subquery returns no
10751 The result is NULL if the comparison does not return true for any row,
10752 and it returns NULL for at least one row.
10756 See <xref linkend="row-wise-comparison
"> for details about the meaning
10757 of a row-wise comparison.
10762 <title><literal>ALL</literal></title>
10765 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10769 The right-hand side is a parenthesized
10770 subquery, which must return exactly one column. The left-hand expression
10771 is evaluated and compared to each row of the subquery result using the
10772 given <replaceable>operator</replaceable>, which must yield a Boolean
10774 The result of <token>ALL</token> is <quote>true</> if all rows yield true
10775 (including the case where the subquery returns no rows).
10776 The result is <quote>false</> if any false result is found.
10777 The result is NULL if the comparison does not return false for any row,
10778 and it returns NULL for at least one row.
10782 <token>NOT IN</token> is equivalent to <literal><> ALL</literal>.
10786 As with <token>EXISTS</token>, it's unwise to assume that the subquery will
10787 be evaluated completely.
10791 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
10795 The left-hand side of this form of <token>ALL</token> is a row constructor,
10796 as described in <xref linkend="sql-syntax-row-constructors
">.
10797 The right-hand side is a parenthesized
10798 subquery, which must return exactly as many columns as there are
10799 expressions in the left-hand row. The left-hand expressions are
10800 evaluated and compared row-wise to each row of the subquery result,
10801 using the given <replaceable>operator</replaceable>.
10802 The result of <token>ALL</token> is <quote>true</> if the comparison
10803 returns true for all subquery rows (including the
10804 case where the subquery returns no rows).
10805 The result is <quote>false</> if the comparison returns false for any
10807 The result is NULL if the comparison does not return false for any
10808 subquery row, and it returns NULL for at least one row.
10812 See <xref linkend="row-wise-comparison
"> for details about the meaning
10813 of a row-wise comparison.
10818 <title>Row-wise Comparison</title>
10820 <indexterm zone="functions-subquery
">
10821 <primary>comparison</primary>
10822 <secondary>subquery result row</secondary>
10826 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
10830 The left-hand side is a row constructor,
10831 as described in <xref linkend="sql-syntax-row-constructors
">.
10832 The right-hand side is a parenthesized subquery, which must return exactly
10833 as many columns as there are expressions in the left-hand row. Furthermore,
10834 the subquery cannot return more than one row. (If it returns zero rows,
10835 the result is taken to be null.) The left-hand side is evaluated and
10836 compared row-wise to the single subquery result row.
10840 See <xref linkend="row-wise-comparison
"> for details about the meaning
10841 of a row-wise comparison.
10847 <sect1 id="functions-comparisons
">
10848 <title>Row and Array Comparisons</title>
10851 <primary>IN</primary>
10855 <primary>NOT IN</primary>
10859 <primary>ANY</primary>
10863 <primary>ALL</primary>
10867 <primary>SOME</primary>
10871 <primary>row-wise comparison</primary>
10875 <primary>comparison</primary>
10876 <secondary>row-wise</secondary>
10880 <primary>IS DISTINCT FROM</primary>
10884 <primary>IS NOT DISTINCT FROM</primary>
10888 This section describes several specialized constructs for making
10889 multiple comparisons between groups of values. These forms are
10890 syntactically related to the subquery forms of the previous section,
10891 but do not involve subqueries.
10892 The forms involving array subexpressions are
10893 <productname>PostgreSQL</productname> extensions; the rest are
10894 <acronym>SQL</acronym>-compliant.
10895 All of the expression forms documented in this section return
10896 Boolean (true/false) results.
10900 <title><literal>IN</literal></title>
10903 <replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10907 The right-hand side is a parenthesized list
10908 of scalar expressions. The result is <quote>true</> if the left-hand expression's
10909 result is equal to any of the right-hand expressions. This is a shorthand
10913 <replaceable>expression</replaceable> = <replaceable>value1</replaceable>
10915 <replaceable>expression</replaceable> = <replaceable>value2</replaceable>
10922 Note that if the left-hand expression yields null, or if there are
10923 no equal right-hand values and at least one right-hand expression yields
10924 null, the result of the <token>IN</token> construct will be null, not false.
10925 This is in accordance with SQL's normal rules for Boolean combinations
10931 <title><literal>NOT IN</literal></title>
10934 <replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
10938 The right-hand side is a parenthesized list
10939 of scalar expressions. The result is <quote>true</quote> if the left-hand expression's
10940 result is unequal to all of the right-hand expressions. This is a shorthand
10944 <replaceable>expression</replaceable> <> <replaceable>value1</replaceable>
10946 <replaceable>expression</replaceable> <> <replaceable>value2</replaceable>
10953 Note that if the left-hand expression yields null, or if there are
10954 no equal right-hand values and at least one right-hand expression yields
10955 null, the result of the <token>NOT IN</token> construct will be null, not true
10956 as one might naively expect.
10957 This is in accordance with SQL's normal rules for Boolean combinations
10963 <literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
10964 cases. However, null values are much more likely to trip up the novice when
10965 working with <token>NOT IN</token> than when working with <token>IN</token>.
10966 It is best to express your condition positively if possible.
10972 <title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
10975 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
10976 <replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
10980 The right-hand side is a parenthesized expression, which must yield an
10982 The left-hand expression
10983 is evaluated and compared to each element of the array using the
10984 given <replaceable>operator</replaceable>, which must yield a Boolean
10986 The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
10987 The result is <quote>false</> if no true result is found (including the
10988 case where the array has zero elements).
10992 If the array expression yields a null array, the result of
10993 <token>ANY</token> will be null. If the left-hand expression yields null,
10994 the result of <token>ANY</token> is ordinarily null (though a non-strict
10995 comparison operator could possibly yield a different result).
10996 Also, if the right-hand array contains any null elements and no true
10997 comparison result is obtained, the result of <token>ANY</token>
10998 will be null, not false (again, assuming a strict comparison operator).
10999 This is in accordance with SQL's normal rules for Boolean combinations
11004 <token>SOME</token> is a synonym for <token>ANY</token>.
11009 <title><literal>ALL</literal> (array)</title>
11012 <replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
11016 The right-hand side is a parenthesized expression, which must yield an
11018 The left-hand expression
11019 is evaluated and compared to each element of the array using the
11020 given <replaceable>operator</replaceable>, which must yield a Boolean
11022 The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
11023 (including the case where the array has zero elements).
11024 The result is <quote>false</> if any false result is found.
11028 If the array expression yields a null array, the result of
11029 <token>ALL</token> will be null. If the left-hand expression yields null,
11030 the result of <token>ALL</token> is ordinarily null (though a non-strict
11031 comparison operator could possibly yield a different result).
11032 Also, if the right-hand array contains any null elements and no false
11033 comparison result is obtained, the result of <token>ALL</token>
11034 will be null, not true (again, assuming a strict comparison operator).
11035 This is in accordance with SQL's normal rules for Boolean combinations
11040 <sect2 id="row-wise-comparison
">
11041 <title>Row-wise Comparison</title>
11044 <replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
11048 Each side is a row constructor,
11049 as described in <xref linkend="sql-syntax-row-constructors
">.
11050 The two row values must have the same number of fields.
11051 Each side is evaluated and they are compared row-wise. Row comparisons
11052 are allowed when the <replaceable>operator</replaceable> is
11054 <literal><></>,
11057 <literal>></> or
11059 or has semantics similar to one of these. (To be specific, an operator
11060 can be a row comparison operator if it is a member of a B-Tree operator
11061 class, or is the negator of the <literal>=</> member of a B-Tree operator
11066 The <literal>=</> and <literal><></> cases work slightly differently
11067 from the others. Two rows are considered
11068 equal if all their corresponding members are non-null and equal; the rows
11069 are unequal if any corresponding members are non-null and unequal;
11070 otherwise the result of the row comparison is unknown (null).
11074 For the <literal><</>, <literal><=</>, <literal>></> and
11075 <literal>>=</> cases, the row elements are compared left-to-right,
11076 stopping as soon as an unequal or null pair of elements is found.
11077 If either of this pair of elements is null, the result of the
11078 row comparison is unknown (null); otherwise comparison of this pair
11079 of elements determines the result. For example,
11080 <literal>ROW(1,2,NULL) < ROW(1,3,0)</>
11081 yields true, not null, because the third pair of elements are not
11087 Prior to <productname>PostgreSQL</productname> 8.2, the
11088 <literal><</>, <literal><=</>, <literal>></> and <literal>>=</>
11089 cases were not handled per SQL specification. A comparison like
11090 <literal>ROW(a,b) < ROW(c,d)</>
11092 <literal>a < c AND b < d</>
11093 whereas the correct behavior is equivalent to
11094 <literal>a < c OR (a = c AND b < d)</>.
11099 <replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
11103 This construct is similar to a <literal><></literal> row comparison,
11104 but it does not yield null for null inputs. Instead, any null value is
11105 considered unequal to (distinct from) any non-null value, and any two
11106 nulls are considered equal (not distinct). Thus the result will
11107 either be true or false, never null.
11111 <replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
11115 This construct is similar to a <literal>=</literal> row comparison,
11116 but it does not yield null for null inputs. Instead, any null value is
11117 considered unequal to (distinct from) any non-null value, and any two
11118 nulls are considered equal (not distinct). Thus the result will always
11119 be either true or false, never null.
11124 The SQL specification requires row-wise comparison to return NULL if the
11125 result depends on comparing two NULL values or a NULL and a non-NULL.
11126 <productname>PostgreSQL</productname> does this only when comparing the
11127 results of two row constructors or comparing a row constructor to the
11128 output of a subquery (as in <xref linkend="functions-subquery
">).
11129 In other contexts where two composite-type values are compared, two
11130 NULL field values are considered equal, and a NULL is considered larger
11131 than a non-NULL. This is necessary in order to have consistent sorting
11132 and indexing behavior for composite types.
11139 <sect1 id="functions-srf
">
11140 <title>Set Returning Functions</title>
11142 <indexterm zone="functions-srf
">
11143 <primary>set returning functions</primary>
11144 <secondary>functions</secondary>
11148 <primary>generate_series</primary>
11152 This section describes functions that possibly return more than one row.
11153 Currently the only functions in this class are series generating functions,
11154 as detailed in <xref linkend="functions-srf-series
"> and
11155 <xref linkend="functions-srf-subscripts
">.
11158 <table id="functions-srf-series
">
11159 <title>Series Generating Functions</title>
11163 <entry>Function</entry>
11164 <entry>Argument Type</entry>
11165 <entry>Return Type</entry>
11166 <entry>Description</entry>
11172 <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>)</literal></entry>
11173 <entry><type>int</type> or <type>bigint</type></entry>
11174 <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11176 Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11177 with a step size of one
11182 <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</literal></entry>
11183 <entry><type>int</type> or <type>bigint</type></entry>
11184 <entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
11186 Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11187 with a step size of <parameter>step</parameter>
11192 <entry><literal><function>generate_series</function>(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</literal></entry>
11193 <entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
11194 <entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
11196 Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
11197 with a step size of <parameter>step</parameter>
11206 When <parameter>step</parameter> is positive, zero rows are returned if
11207 <parameter>start</parameter> is greater than <parameter>stop</parameter>.
11208 Conversely, when <parameter>step</parameter> is negative, zero rows are
11209 returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
11210 Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
11211 for <parameter>step</parameter> to be zero. Some examples follow:
11213 SELECT * FROM generate_series(2,4);
11221 SELECT * FROM generate_series(5,1,-2);
11229 SELECT * FROM generate_series(4,3);
11234 -- this example relies on the date-plus-integer operator
11235 SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
11243 SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
11244 '2008-03-04 12:00', '10 hours');
11246 ---------------------
11247 2008-03-01 00:00:00
11248 2008-03-01 10:00:00
11249 2008-03-01 20:00:00
11250 2008-03-02 06:00:00
11251 2008-03-02 16:00:00
11252 2008-03-03 02:00:00
11253 2008-03-03 12:00:00
11254 2008-03-03 22:00:00
11255 2008-03-04 08:00:00
11260 <table id="functions-srf-subscripts
">
11261 <title>Subscript Generating Functions</title>
11265 <entry>Function</entry>
11266 <entry>Return Type</entry>
11267 <entry>Description</entry>
11273 <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</literal></entry>
11274 <entry><type>setof int</type></entry>
11276 Generate a series comprising the given array's subscripts.
11281 <entry><literal><function>generate_subscripts</function>(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</literal></entry>
11282 <entry><type>setof int</type></entry>
11284 Generate a series comprising the given array's subscripts. When
11285 <parameter>reverse</parameter> is true, the series is returned in
11295 <primary>generate_subscripts</primary>
11299 <function>generate_subscripts</> is a convenience function that generates
11300 the set of valid subscripts for the specified dimension of the given
11302 Zero rows are returned for arrays that do not have the requested dimension,
11303 or for NULL arrays (but valid subscripts are returned for NULL array
11304 elements). Some examples follow:
11307 select generate_subscripts('{NULL,1,NULL,2}'::int[], 1) as s;
11316 -- presenting an array, the subscript and the subscripted
11317 -- value requires a subquery
11318 select * from arrays;
11320 --------------------
11325 select a as array, s as subscript, a[s] as value
11326 from (select generate_subscripts(a, 1) as s, a from arrays) foo;
11327 array | subscript | value
11328 -----------+-----------+-------
11331 {100,200} | 1 | 100
11332 {100,200} | 2 | 200
11335 -- unnest a 2D array
11336 create or replace function unnest2(anyarray)
11337 returns setof anyelement as $$
11339 from generate_subscripts($1,1) g1(i),
11340 generate_subscripts($1,2) g2(j);
11341 $$ language sql immutable;
11343 postgres=# select * from unnest2(array[[1,2],[3,4]]);
11356 <sect1 id="functions-info
">
11357 <title>System Information Functions</title>
11360 <xref linkend="functions-info-session-table
"> shows several
11361 functions that extract session and system information.
11365 In addition to the functions listed in this section, there are a number of
11366 functions related to the statistics system that also provide system
11367 information. See <xref linkend="monitoring-stats-views
"> for more
11371 <table id="functions-info-session-table
">
11372 <title>Session Information Functions</title>
11375 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11380 <entry><literal><function>current_catalog</function></literal></entry>
11381 <entry><type>name</type></entry>
11382 <entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
11386 <entry><literal><function>current_database</function>()</literal></entry>
11387 <entry><type>name</type></entry>
11388 <entry>name of current database</entry>
11392 <entry><literal><function>current_schema</function>[()]</literal></entry>
11393 <entry><type>name</type></entry>
11394 <entry>name of current schema</entry>
11398 <entry><literal><function>current_schemas</function>(<type>boolean</type>)</literal></entry>
11399 <entry><type>name[]</type></entry>
11400 <entry>names of schemas in search path optionally including implicit schemas</entry>
11404 <entry><literal><function>current_user</function></literal></entry>
11405 <entry><type>name</type></entry>
11406 <entry>user name of current execution context</entry>
11410 <entry><literal><function>current_query</function></literal></entry>
11411 <entry><type>text</type></entry>
11412 <entry>text of the currently executing query, as submitted
11413 by the client (might contain more than one statement)</entry>
11417 <!-- See also the entry for this in monitoring.sgml -->
11418 <entry><literal><function>pg_backend_pid</function>()</literal></entry>
11419 <entry><type>int</type></entry>
11421 Process ID of the server process attached to the current session
11426 <entry><literal><function>inet_client_addr</function>()</literal></entry>
11427 <entry><type>inet</type></entry>
11428 <entry>address of the remote connection</entry>
11432 <entry><literal><function>inet_client_port</function>()</literal></entry>
11433 <entry><type>int</type></entry>
11434 <entry>port of the remote connection</entry>
11438 <entry><literal><function>inet_server_addr</function>()</literal></entry>
11439 <entry><type>inet</type></entry>
11440 <entry>address of the local connection</entry>
11444 <entry><literal><function>inet_server_port</function>()</literal></entry>
11445 <entry><type>int</type></entry>
11446 <entry>port of the local connection</entry>
11450 <entry><literal><function>pg_my_temp_schema</function>()</literal></entry>
11451 <entry><type>oid</type></entry>
11452 <entry>OID of session's temporary schema, or 0 if none</entry>
11456 <entry><literal><function>pg_is_other_temp_schema</function>(<type>oid</type>)</literal></entry>
11457 <entry><type>boolean</type></entry>
11458 <entry>is schema another session's temporary schema?</entry>
11462 <entry><literal><function>pg_postmaster_start_time</function>()</literal></entry>
11463 <entry><type>timestamp with time zone</type></entry>
11464 <entry>server start time</entry>
11468 <entry><literal><function>pg_conf_load_time</function>()</literal></entry>
11469 <entry><type>timestamp with time zone</type></entry>
11470 <entry>configuration load time</entry>
11474 <entry><literal><function>session_user</function></literal></entry>
11475 <entry><type>name</type></entry>
11476 <entry>session user name</entry>
11480 <entry><literal><function>user</function></literal></entry>
11481 <entry><type>name</type></entry>
11482 <entry>equivalent to <function>current_user</function></entry>
11486 <entry><literal><function>version</function>()</literal></entry>
11487 <entry><type>text</type></entry>
11488 <entry><productname>PostgreSQL</> version information</entry>
11495 <primary>user</primary>
11496 <secondary>current</secondary>
11500 <primary>schema</primary>
11501 <secondary>current</secondary>
11505 <primary>search path</primary>
11506 <secondary>current</secondary>
11510 <primary>current_catalog</primary>
11514 <primary>current_database</primary>
11518 <primary>current_schema</primary>
11522 <primary>current_user</primary>
11526 The <function>session_user</function> is normally the user who initiated
11527 the current database connection; but superusers can change this setting
11528 with <xref linkend="sql-set-session-authorization
" endterm="sql-set-session-authorization-title
">.
11529 The <function>current_user</function> is the user identifier
11530 that is applicable for permission checking. Normally it is equal
11531 to the session user, but it can be changed with
11532 <xref linkend="sql-set-role
" endterm="sql-set-role-title
">.
11533 It also changes during the execution of
11534 functions with the attribute <literal>SECURITY DEFINER</literal>.
11535 In Unix parlance, the session user is the <quote>real user</quote> and
11536 the current user is the <quote>effective user</quote>.
11541 <function>current_catalog</function>, <function>current_schema</function>,
11542 <function>current_user</function>, <function>session_user</function>,
11543 and <function>user</function> have special syntactic status
11544 in <acronym>SQL</acronym>: they must be called without trailing
11545 parentheses (optional in PostgreSQL in the case
11546 of <function>current_schema</function>).
11551 <function>current_schema</function> returns the name of the schema that is
11552 first in the search path (or a null value if the search path is
11553 empty). This is the schema that will be used for any tables or
11554 other named objects that are created without specifying a target schema.
11555 <function>current_schemas(boolean)</function> returns an array of the names of all
11556 schemas presently in the search path. The Boolean option determines whether or not
11557 implicitly included system schemas such as <literal>pg_catalog</> are included in the
11558 returned search path.
11563 The search path can be altered at run time. The command is:
11565 SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
11571 <primary>inet_client_addr</primary>
11575 <primary>inet_client_port</primary>
11579 <primary>inet_server_addr</primary>
11583 <primary>inet_server_port</primary>
11587 <function>inet_client_addr</function> returns the IP address of the
11588 current client, and <function>inet_client_port</function> returns the
11590 <function>inet_server_addr</function> returns the IP address on which
11591 the server accepted the current connection, and
11592 <function>inet_server_port</function> returns the port number.
11593 All these functions return NULL if the current connection is via a
11594 Unix-domain socket.
11598 <primary>pg_my_temp_schema</primary>
11602 <primary>pg_is_other_temp_schema</primary>
11606 <function>pg_my_temp_schema</function> returns the OID of the current
11607 session's temporary schema, or zero if it has none (because it has not
11608 created any temporary tables).
11609 <function>pg_is_other_temp_schema</function> returns true if the
11610 given OID is the OID of another session's temporary schema.
11611 (This can be useful, for example, to exclude other sessions' temporary
11612 tables from a catalog display.)
11616 <primary>pg_postmaster_start_time</primary>
11620 <function>pg_postmaster_start_time</function> returns the
11621 <type>timestamp with time zone</type> when the
11626 <primary>pg_conf_load_time</primary>
11630 <function>pg_conf_load_time</function> returns the
11631 <type>timestamp with time zone</type> when the
11632 server configuration files were last loaded.
11633 (If the current session was alive at the time, this will be the time
11634 when the session itself re-read the configuration files, so the
11635 reading will vary a little in different sessions. Otherwise it is
11636 the time when the postmaster process re-read the configuration files.)
11640 <primary>version</primary>
11644 <function>version</function> returns a string describing the
11645 <productname>PostgreSQL</productname> server's version.
11649 <primary>privilege</primary>
11650 <secondary>querying</secondary>
11654 <xref linkend="functions-info-access-table
"> lists functions that
11655 allow the user to query object access privileges programmatically.
11656 See <xref linkend="ddl-priv
"> for more information about
11660 <table id="functions-info-access-table
">
11661 <title>Access Privilege Inquiry Functions</title>
11664 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
11669 <entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
11670 <parameter>table</parameter>,
11671 <parameter>privilege</parameter>)</literal>
11673 <entry><type>boolean</type></entry>
11674 <entry>does user have privilege for any column of table</entry>
11677 <entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
11678 <parameter>privilege</parameter>)</literal>
11680 <entry><type>boolean</type></entry>
11681 <entry>does current user have privilege for any column of table</entry>
11684 <entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
11685 <parameter>table</parameter>,
11686 <parameter>column</parameter>,
11687 <parameter>privilege</parameter>)</literal>
11689 <entry><type>boolean</type></entry>
11690 <entry>does user have privilege for column</entry>
11693 <entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
11694 <parameter>column</parameter>,
11695 <parameter>privilege</parameter>)</literal>
11697 <entry><type>boolean</type></entry>
11698 <entry>does current user have privilege for column</entry>
11701 <entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
11702 <parameter>database</parameter>,
11703 <parameter>privilege</parameter>)</literal>
11705 <entry><type>boolean</type></entry>
11706 <entry>does user have privilege for database</entry>
11709 <entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
11710 <parameter>privilege</parameter>)</literal>
11712 <entry><type>boolean</type></entry>
11713 <entry>does current user have privilege for database</entry>
11716 <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
11717 <parameter>fdw</parameter>,
11718 <parameter>privilege</parameter>)</literal>
11720 <entry><type>boolean</type></entry>
11721 <entry>does user have privilege for foreign-data wrapper</entry>
11724 <entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
11725 <parameter>privilege</parameter>)</literal>
11727 <entry><type>boolean</type></entry>
11728 <entry>does current user have privilege for foreign-data wrapper</entry>
11731 <entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
11732 <parameter>function</parameter>,
11733 <parameter>privilege</parameter>)</literal>
11735 <entry><type>boolean</type></entry>
11736 <entry>does user have privilege for function</entry>
11739 <entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
11740 <parameter>privilege</parameter>)</literal>
11742 <entry><type>boolean</type></entry>
11743 <entry>does current user have privilege for function</entry>
11746 <entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
11747 <parameter>language</parameter>,
11748 <parameter>privilege</parameter>)</literal>
11750 <entry><type>boolean</type></entry>
11751 <entry>does user have privilege for language</entry>
11754 <entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
11755 <parameter>privilege</parameter>)</literal>
11757 <entry><type>boolean</type></entry>
11758 <entry>does current user have privilege for language</entry>
11761 <entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
11762 <parameter>schema</parameter>,
11763 <parameter>privilege</parameter>)</literal>
11765 <entry><type>boolean</type></entry>
11766 <entry>does user have privilege for schema</entry>
11769 <entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
11770 <parameter>privilege</parameter>)</literal>
11772 <entry><type>boolean</type></entry>
11773 <entry>does current user have privilege for schema</entry>
11776 <entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
11777 <parameter>server</parameter>,
11778 <parameter>privilege</parameter>)</literal>
11780 <entry><type>boolean</type></entry>
11781 <entry>does user have privilege for foreign server</entry>
11784 <entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
11785 <parameter>privilege</parameter>)</literal>
11787 <entry><type>boolean</type></entry>
11788 <entry>does current user have privilege for foreign server</entry>
11791 <entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
11792 <parameter>table</parameter>,
11793 <parameter>privilege</parameter>)</literal>
11795 <entry><type>boolean</type></entry>
11796 <entry>does user have privilege for table</entry>
11799 <entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
11800 <parameter>privilege</parameter>)</literal>
11802 <entry><type>boolean</type></entry>
11803 <entry>does current user have privilege for table</entry>
11806 <entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
11807 <parameter>tablespace</parameter>,
11808 <parameter>privilege</parameter>)</literal>
11810 <entry><type>boolean</type></entry>
11811 <entry>does user have privilege for tablespace</entry>
11814 <entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
11815 <parameter>privilege</parameter>)</literal>
11817 <entry><type>boolean</type></entry>
11818 <entry>does current user have privilege for tablespace</entry>
11821 <entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
11822 <parameter>role</parameter>,
11823 <parameter>privilege</parameter>)</literal>
11825 <entry><type>boolean</type></entry>
11826 <entry>does user have privilege for role</entry>
11829 <entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
11830 <parameter>privilege</parameter>)</literal>
11832 <entry><type>boolean</type></entry>
11833 <entry>does current user have privilege for role</entry>
11840 <primary>has_any_column_privilege</primary>
11843 <primary>has_column_privilege</primary>
11846 <primary>has_database_privilege</primary>
11849 <primary>has_function_privilege</primary>
11852 <primary>has_foreign_data_wrapper_privilege</primary>
11855 <primary>has_language_privilege</primary>
11858 <primary>has_schema_privilege</primary>
11861 <primary>has_server_privilege</primary>
11864 <primary>has_table_privilege</primary>
11867 <primary>has_tablespace_privilege</primary>
11870 <primary>pg_has_role</primary>
11874 <function>has_table_privilege</function> checks whether a user
11875 can access a table in a particular way. The user can be
11876 specified by name or by OID
11877 (<literal>pg_authid.oid</literal>), or if the argument is
11879 <function>current_user</function> is assumed. The table can be specified
11880 by name or by OID. (Thus, there are actually six variants of
11881 <function>has_table_privilege</function>, which can be distinguished by
11882 the number and types of their arguments.) When specifying by name,
11883 the name can be schema-qualified if necessary.
11884 The desired access privilege type
11885 is specified by a text string, which must evaluate to one of the
11886 values <literal>SELECT</literal>, <literal>INSERT</literal>,
11887 <literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
11888 <literal>REFERENCES</literal>, or <literal>TRIGGER</literal>. Optionally,
11889 <literal>WITH GRANT OPTION</> can be added to a privilege type to test
11890 whether the privilege is held with grant option. Also, multiple privilege
11891 types can be listed separated by commas, in which case the result will
11892 be <literal>true</> if any of the listed privileges is held.
11893 (Case of the privilege string is not significant, and extra whitespace
11894 is allowed between but not within privilege names.)
11897 SELECT has_table_privilege('myschema.mytable', 'select');
11898 SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
11903 <function>has_any_column_privilege</function> checks whether a user can
11904 access any column of a table in a particular way.
11905 Its argument possibilities
11906 are analogous to <function>has_table_privilege</>,
11907 except that the desired access privilege type must evaluate to some
11909 <literal>SELECT</literal>,
11910 <literal>INSERT</literal>,
11911 <literal>UPDATE</literal>, or
11912 <literal>REFERENCES</literal>. Note that having any of these privileges
11913 at the table level implicitly grants it for each column of the table,
11914 so <function>has_any_column_privilege</function> will always return
11915 <literal>true</> if <function>has_table_privilege</> does for the same
11916 arguments. But <function>has_any_column_privilege</> also succeeds if
11917 there is a column-level grant of the privilege for at least one column.
11921 <function>has_column_privilege</function> checks whether a user
11922 can access a column in a particular way.
11923 Its argument possibilities
11924 are analogous to <function>has_table_privilege</function>,
11925 with the addition that the column can be specified either by name
11926 or attribute number.
11927 The desired access privilege type must evaluate to some combination of
11928 <literal>SELECT</literal>,
11929 <literal>INSERT</literal>,
11930 <literal>UPDATE</literal>, or
11931 <literal>REFERENCES</literal>. Note that having any of these privileges
11932 at the table level implicitly grants it for each column of the table.
11936 <function>has_database_privilege</function> checks whether a user
11937 can access a database in a particular way.
11938 Its argument possibilities
11939 are analogous to <function>has_table_privilege</function>.
11940 The desired access privilege type must evaluate to some combination of
11941 <literal>CREATE</literal>,
11942 <literal>CONNECT</literal>,
11943 <literal>TEMPORARY</literal>, or
11944 <literal>TEMP</literal> (which is equivalent to
11945 <literal>TEMPORARY</literal>).
11949 <function>has_function_privilege</function> checks whether a user
11950 can access a function in a particular way.
11951 Its argument possibilities
11952 are analogous to <function>has_table_privilege</function>.
11953 When specifying a function by a text string rather than by OID,
11954 the allowed input is the same as for the <type>regprocedure</> data type
11955 (see <xref linkend="datatype-oid
">).
11956 The desired access privilege type must evaluate to
11957 <literal>EXECUTE</literal>.
11960 SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
11965 <function>has_foreign_data_wrapper_privilege</function> checks whether a user
11966 can access a foreign-data wrapper in a particular way.
11967 Its argument possibilities
11968 are analogous to <function>has_table_privilege</function>.
11969 The desired access privilege type must evaluate to
11970 <literal>USAGE</literal>.
11974 <function>has_language_privilege</function> checks whether a user
11975 can access a procedural language in a particular way.
11976 Its argument possibilities
11977 are analogous to <function>has_table_privilege</function>.
11978 The desired access privilege type must evaluate to
11979 <literal>USAGE</literal>.
11983 <function>has_schema_privilege</function> checks whether a user
11984 can access a schema in a particular way.
11985 Its argument possibilities
11986 are analogous to <function>has_table_privilege</function>.
11987 The desired access privilege type must evaluate to some combination of
11988 <literal>CREATE</literal> or
11989 <literal>USAGE</literal>.
11993 <function>has_server_privilege</function> checks whether a user
11994 can access a foreign server in a particular way.
11995 Its argument possibilities
11996 are analogous to <function>has_table_privilege</function>.
11997 The desired access privilege type must evaluate to
11998 <literal>USAGE</literal>.
12002 <function>has_tablespace_privilege</function> checks whether a user
12003 can access a tablespace in a particular way.
12004 Its argument possibilities
12005 are analogous to <function>has_table_privilege</function>.
12006 The desired access privilege type must evaluate to
12007 <literal>CREATE</literal>.
12011 <function>pg_has_role</function> checks whether a user
12012 can access a role in a particular way.
12013 Its argument possibilities
12014 are analogous to <function>has_table_privilege</function>.
12015 The desired access privilege type must evaluate to some combination of
12016 <literal>MEMBER</literal> or
12017 <literal>USAGE</literal>.
12018 <literal>MEMBER</literal> denotes direct or indirect membership in
12019 the role (that is, the right to do <command>SET ROLE</>), while
12020 <literal>USAGE</literal> denotes whether the privileges of the role
12021 are immediately available without doing <command>SET ROLE</>.
12025 <xref linkend="functions-info-schema-table
"> shows functions that
12026 determine whether a certain object is <firstterm>visible</> in the
12027 current schema search path.
12028 For example, a table is said to be visible if its
12029 containing schema is in the search path and no table of the same
12030 name appears earlier in the search path. This is equivalent to the
12031 statement that the table can be referenced by name without explicit
12032 schema qualification. To list the names of all visible tables:
12034 SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
12038 <table id="functions-info-schema-table
">
12039 <title>Schema Visibility Inquiry Functions</title>
12042 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12047 <entry><literal><function>pg_conversion_is_visible</function>(<parameter>conversion_oid</parameter>)</literal>
12049 <entry><type>boolean</type></entry>
12050 <entry>is conversion visible in search path</entry>
12053 <entry><literal><function>pg_function_is_visible</function>(<parameter>function_oid</parameter>)</literal>
12055 <entry><type>boolean</type></entry>
12056 <entry>is function visible in search path</entry>
12059 <entry><literal><function>pg_operator_is_visible</function>(<parameter>operator_oid</parameter>)</literal>
12061 <entry><type>boolean</type></entry>
12062 <entry>is operator visible in search path</entry>
12065 <entry><literal><function>pg_opclass_is_visible</function>(<parameter>opclass_oid</parameter>)</literal>
12067 <entry><type>boolean</type></entry>
12068 <entry>is operator class visible in search path</entry>
12071 <entry><literal><function>pg_table_is_visible</function>(<parameter>table_oid</parameter>)</literal>
12073 <entry><type>boolean</type></entry>
12074 <entry>is table visible in search path</entry>
12077 <entry><literal><function>pg_ts_config_is_visible</function>(<parameter>config_oid</parameter>)</literal>
12079 <entry><type>boolean</type></entry>
12080 <entry>is text search configuration visible in search path</entry>
12083 <entry><literal><function>pg_ts_dict_is_visible</function>(<parameter>dict_oid</parameter>)</literal>
12085 <entry><type>boolean</type></entry>
12086 <entry>is text search dictionary visible in search path</entry>
12089 <entry><literal><function>pg_ts_parser_is_visible</function>(<parameter>parser_oid</parameter>)</literal>
12091 <entry><type>boolean</type></entry>
12092 <entry>is text search parser visible in search path</entry>
12095 <entry><literal><function>pg_ts_template_is_visible</function>(<parameter>template_oid</parameter>)</literal>
12097 <entry><type>boolean</type></entry>
12098 <entry>is text search template visible in search path</entry>
12101 <entry><literal><function>pg_type_is_visible</function>(<parameter>type_oid</parameter>)</literal>
12103 <entry><type>boolean</type></entry>
12104 <entry>is type (or domain) visible in search path</entry>
12111 <primary>pg_conversion_is_visible</primary>
12114 <primary>pg_function_is_visible</primary>
12117 <primary>pg_operator_is_visible</primary>
12120 <primary>pg_opclass_is_visible</primary>
12123 <primary>pg_table_is_visible</primary>
12126 <primary>pg_ts_config_is_visible</primary>
12129 <primary>pg_ts_dict_is_visible</primary>
12132 <primary>pg_ts_parser_is_visible</primary>
12135 <primary>pg_ts_template_is_visible</primary>
12138 <primary>pg_type_is_visible</primary>
12142 Each function performs the visibility check for one type of database
12143 object. Note that <function>pg_table_is_visible</function> can also be used
12144 with views, indexes and sequences; <function>pg_type_is_visible</function>
12145 can also be used with domains. For functions and operators, an object in
12146 the search path is visible if there is no object of the same name
12147 <emphasis>and argument data type(s)</> earlier in the path. For operator
12148 classes, both name and associated index access method are considered.
12152 All these functions require object OIDs to identify the object to be
12153 checked. If you want to test an object by name, it is convenient to use
12154 the OID alias types (<type>regclass</>, <type>regtype</>,
12155 <type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
12156 or <type>regdictionary</>),
12159 SELECT pg_type_is_visible('myschema.widget'::regtype);
12161 Note that it would not make much sense to test a non-schema-qualified
12162 type name in this way — if the name can be recognized at all, it must be visible.
12166 <primary>format_type</primary>
12170 <primary>pg_get_keywords</primary>
12174 <primary>pg_get_viewdef</primary>
12178 <primary>pg_get_ruledef</primary>
12182 <primary>pg_get_functiondef</primary>
12186 <primary>pg_get_function_arguments</primary>
12190 <primary>pg_get_function_identity_arguments</primary>
12194 <primary>pg_get_function_result</primary>
12198 <primary>pg_get_indexdef</primary>
12202 <primary>pg_get_triggerdef</primary>
12206 <primary>pg_get_constraintdef</primary>
12210 <primary>pg_get_expr</primary>
12214 <primary>pg_get_userbyid</primary>
12218 <primary>pg_get_serial_sequence</primary>
12222 <primary>pg_tablespace_databases</primary>
12226 <primary>pg_typeof</primary>
12230 <xref linkend="functions-info-catalog-table
"> lists functions that
12231 extract information from the system catalogs.
12234 <table id="functions-info-catalog-table
">
12235 <title>System Catalog Information Functions</title>
12238 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12243 <entry><literal><function>format_type</function>(<parameter>type_oid</parameter>, <parameter>typemod</>)</literal></entry>
12244 <entry><type>text</type></entry>
12245 <entry>get SQL name of a data type</entry>
12248 <entry><literal><function>pg_get_keywords</function>()</literal></entry>
12249 <entry><type>setof record</type></entry>
12250 <entry>get list of SQL keywords and their categories</entry>
12253 <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>)</literal></entry>
12254 <entry><type>text</type></entry>
12255 <entry>get definition of a constraint</entry>
12258 <entry><literal><function>pg_get_constraintdef</function>(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12259 <entry><type>text</type></entry>
12260 <entry>get definition of a constraint</entry>
12263 <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>)</literal></entry>
12264 <entry><type>text</type></entry>
12265 <entry>decompile internal form of an expression, assuming that any Vars
12266 in it refer to the relation indicated by the second parameter</entry>
12269 <entry><literal><function>pg_get_expr</function>(<parameter>expr_text</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</literal></entry>
12270 <entry><type>text</type></entry>
12271 <entry>decompile internal form of an expression, assuming that any Vars
12272 in it refer to the relation indicated by the second parameter</entry>
12275 <entry><literal><function>pg_get_functiondef</function>(<parameter>func_oid</parameter>)</literal></entry>
12276 <entry><type>text</type></entry>
12277 <entry>get definition of a function</entry>
12280 <entry><literal><function>pg_get_function_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
12281 <entry><type>text</type></entry>
12282 <entry>get argument list of function's definition (with default values)</entry>
12285 <entry><literal><function>pg_get_function_identity_arguments</function>(<parameter>func_oid</parameter>)</literal></entry>
12286 <entry><type>text</type></entry>
12287 <entry>get argument list to identify a function (without default values)</entry>
12290 <entry><literal><function>pg_get_function_result</function>(<parameter>func_oid</parameter>)</literal></entry>
12291 <entry><type>text</type></entry>
12292 <entry>get <literal>RETURNS</> clause for function</entry>
12295 <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>)</literal></entry>
12296 <entry><type>text</type></entry>
12297 <entry>get <command>CREATE INDEX</> command for index</entry>
12300 <entry><literal><function>pg_get_indexdef</function>(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</literal></entry>
12301 <entry><type>text</type></entry>
12302 <entry>get <command>CREATE INDEX</> command for index,
12303 or definition of just one index column when
12304 <parameter>column_no</> is not zero</entry>
12307 <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>)</literal></entry>
12308 <entry><type>text</type></entry>
12309 <entry>get <command>CREATE RULE</> command for rule</entry>
12312 <entry><literal><function>pg_get_ruledef</function>(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12313 <entry><type>text</type></entry>
12314 <entry>get <command>CREATE RULE</> command for rule</entry>
12317 <entry><literal><function>pg_get_serial_sequence</function>(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</literal></entry>
12318 <entry><type>text</type></entry>
12319 <entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
12323 <entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
12324 <entry><type>text</type></entry>
12325 <entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
12328 <entry><literal><function>pg_get_userbyid</function>(<parameter>role_oid</parameter>)</literal></entry>
12329 <entry><type>name</type></entry>
12330 <entry>get role name with given OID</entry>
12333 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>)</literal></entry>
12334 <entry><type>text</type></entry>
12335 <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
12338 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</literal></entry>
12339 <entry><type>text</type></entry>
12340 <entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
12343 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>)</literal></entry>
12344 <entry><type>text</type></entry>
12345 <entry>get underlying <command>SELECT</command> command for view</entry>
12348 <entry><literal><function>pg_get_viewdef</function>(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</literal></entry>
12349 <entry><type>text</type></entry>
12350 <entry>get underlying <command>SELECT</command> command for view</entry>
12353 <entry><literal><function>pg_tablespace_databases</function>(<parameter>tablespace_oid</parameter>)</literal></entry>
12354 <entry><type>setof oid</type></entry>
12355 <entry>get the set of database OIDs that have objects in the tablespace</entry>
12358 <entry><literal><function>pg_typeof</function>(<parameter>any</parameter>)</literal></entry>
12359 <entry><type>regtype</type></entry>
12360 <entry>get the data type of any value</entry>
12367 <function>format_type</function> returns the SQL name of a data type that
12368 is identified by its type OID and possibly a type modifier. Pass NULL
12369 for the type modifier if no specific modifier is known.
12373 <function>pg_get_keywords</function> returns a set of records describing
12374 the SQL keywords recognized by the server. The <structfield>word</> column
12375 contains the keyword. The <structfield>catcode</> column contains a
12376 category code: <literal>U</> for unreserved, <literal>C</> for column name,
12377 <literal>T</> for type or function name, or <literal>R</> for reserved.
12378 The <structfield>catdesc</> column contains a possibly-localized string
12379 describing the category.
12383 <function>pg_get_constraintdef</function>,
12384 <function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
12385 and <function>pg_get_triggerdef</function>, respectively reconstruct the
12386 creating command for a constraint, index, rule, or trigger. (Note that this
12387 is a decompiled reconstruction, not the original text of the command.)
12388 <function>pg_get_expr</function> decompiles the internal form of an
12389 individual expression, such as the default value for a column. It can be
12390 useful when examining the contents of system catalogs. If the expression
12391 might contain Vars, specify the OID of the relation they refer to as the
12392 second parameter; if no Vars are expected, zero is sufficient.
12393 <function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
12394 query that defines a view. Most of these functions come in two variants,
12395 one of which can optionally <quote>pretty-print</> the result. The
12396 pretty-printed format is more readable, but the default format is more
12397 likely to be interpreted the same way by future versions of
12398 <productname>PostgreSQL</>; avoid using pretty-printed output for dump
12399 purposes. Passing <literal>false</> for the pretty-print parameter yields
12400 the same result as the variant that does not have the parameter at all.
12404 <function>pg_get_functiondef</> returns a complete
12405 <command>CREATE OR REPLACE FUNCTION</> statement for a function.
12406 <function>pg_get_function_arguments</function> returns the argument list
12407 of a function, in the form it would need to appear in within
12408 <command>CREATE FUNCTION</>.
12409 <function>pg_get_function_result</function> similarly returns the
12410 appropriate <literal>RETURNS</> clause for the function.
12411 <function>pg_get_function_identity_arguments</function> returns the
12412 argument list necessary to identify a function, in the form it
12413 would need to appear in within <command>ALTER FUNCTION</>, for
12414 instance. This form omits default values.
12418 <function>pg_get_serial_sequence</function> returns the name of the
12419 sequence associated with a column, or NULL if no sequence is associated
12420 with the column. The first input parameter is a table name with
12421 optional schema, and the second parameter is a column name. Because
12422 the first parameter is potentially a schema and table, it is not treated
12423 as a double-quoted identifier, meaning it is lowercased by default,
12424 while the second parameter, being just a column name, is treated as
12425 double-quoted and has its case preserved. The function returns a value
12426 suitably formatted for passing to sequence functions (see <xref
12427 linkend="functions-sequence
">). This association can be modified or
12428 removed with <command>ALTER SEQUENCE OWNED BY</>. (The function
12429 probably should have been called
12430 <function>pg_get_owned_sequence</function>; its current name reflects the fact
12431 that it's typically used with <type>serial</> or <type>bigserial</>
12436 <function>pg_get_userbyid</function> extracts a role's name given
12441 <function>pg_tablespace_databases</function> allows a tablespace to be
12442 examined. It returns the set of OIDs of databases that have objects stored
12443 in the tablespace. If this function returns any rows, the tablespace is not
12444 empty and cannot be dropped. To display the specific objects populating the
12445 tablespace, you will need to connect to the databases identified by
12446 <function>pg_tablespace_databases</function> and query their
12447 <structname>pg_class</> catalogs.
12451 <function>pg_typeof</function> returns the OID of the data type of the
12452 value that is passed to it. This can be helpful for troubleshooting or
12453 dynamically constructing SQL queries. The function is declared as
12454 returning <type>regtype</>, which is an OID alias type (see
12455 <xref linkend="datatype-oid
">); this means that it is the same as an
12456 OID for comparison purposes but displays as a type name. For example:
12458 SELECT pg_typeof(33);
12465 SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
12474 <primary>col_description</primary>
12478 <primary>obj_description</primary>
12482 <primary>shobj_description</primary>
12486 <primary>comment</primary>
12487 <secondary sortas="database objects
">about database objects</secondary>
12491 The functions shown in <xref linkend="functions-info-comment-table
">
12492 extract comments previously stored with the <xref linkend="sql-comment
"
12493 endterm="sql-comment-title
"> command. A null value is returned if no
12494 comment could be found for the specified parameters.
12497 <table id="functions-info-comment-table
">
12498 <title>Comment Information Functions</title>
12501 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12506 <entry><literal><function>col_description</function>(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</literal></entry>
12507 <entry><type>text</type></entry>
12508 <entry>get comment for a table column</entry>
12511 <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12512 <entry><type>text</type></entry>
12513 <entry>get comment for a database object</entry>
12516 <entry><literal><function>obj_description</function>(<parameter>object_oid</parameter>)</literal></entry>
12517 <entry><type>text</type></entry>
12518 <entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
12521 <entry><literal><function>shobj_description</function>(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</literal></entry>
12522 <entry><type>text</type></entry>
12523 <entry>get comment for a shared database object</entry>
12530 <function>col_description</function> returns the comment for a table column,
12531 which is specified by the OID of its table and its column number.
12532 <function>obj_description</function> cannot be used for table columns since
12533 columns do not have OIDs of their own.
12537 The two-parameter form of <function>obj_description</function> returns the
12538 comment for a database object specified by its OID and the name of the
12539 containing system catalog. For example,
12540 <literal>obj_description(123456,'pg_class')</literal>
12541 would retrieve the comment for the table with OID 123456.
12542 The one-parameter form of <function>obj_description</function> requires only
12543 the object OID. It is deprecated since there is no guarantee that
12544 OIDs are unique across different system catalogs; therefore, the wrong
12545 comment might be returned.
12549 <function>shobj_description</function> is used just like
12550 <function>obj_description</function> except it is used for retrieving
12551 comments on shared objects. Some system catalogs are global to all
12552 databases within each cluster and their descriptions are stored globally
12557 <primary>txid_current</primary>
12561 <primary>txid_current_snapshot</primary>
12565 <primary>txid_snapshot_xmin</primary>
12569 <primary>txid_snapshot_xmax</primary>
12573 <primary>txid_snapshot_xip</primary>
12577 <primary>txid_visible_in_snapshot</primary>
12581 The functions shown in <xref linkend="functions-txid-snapshot
">
12582 provide server transaction information in an exportable form. The main
12583 use of these functions is to determine which transactions were committed
12584 between two snapshots.
12587 <table id="functions-txid-snapshot
">
12588 <title>Transaction IDs and snapshots</title>
12591 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12596 <entry><literal><function>txid_current</function>()</literal></entry>
12597 <entry><type>bigint</type></entry>
12598 <entry>get current transaction ID</entry>
12601 <entry><literal><function>txid_current_snapshot</function>()</literal></entry>
12602 <entry><type>txid_snapshot</type></entry>
12603 <entry>get current snapshot</entry>
12606 <entry><literal><function>txid_snapshot_xmin</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12607 <entry><type>bigint</type></entry>
12608 <entry>get xmin of snapshot</entry>
12611 <entry><literal><function>txid_snapshot_xmax</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12612 <entry><type>bigint</type></entry>
12613 <entry>get xmax of snapshot</entry>
12616 <entry><literal><function>txid_snapshot_xip</function>(<parameter>txid_snapshot</parameter>)</literal></entry>
12617 <entry><type>setof bigint</type></entry>
12618 <entry>get in-progress transaction IDs in snapshot</entry>
12621 <entry><literal><function>txid_visible_in_snapshot</function>(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</literal></entry>
12622 <entry><type>boolean</type></entry>
12623 <entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
12630 The internal transaction ID type (<type>xid</>) is 32 bits wide and
12631 wraps around every 4 billion transactions. However, these functions
12632 export a 64-bit format that is extended with an <quote>epoch</> counter
12633 so it will not wrap around during the life of an installation.
12634 The data type used by these functions, <type>txid_snapshot</type>,
12635 stores information about transaction ID
12636 visibility at a particular moment in time. Its components are
12637 described in <xref linkend="functions-txid-snapshot-parts
">.
12640 <table id="functions-txid-snapshot-parts
">
12641 <title>Snapshot components</title>
12645 <entry>Name</entry>
12646 <entry>Description</entry>
12653 <entry><type>xmin</type></entry>
12655 Earliest transaction ID (txid) that is still active. All earlier
12656 transactions will either be committed and visible, or rolled
12662 <entry><type>xmax</type></entry>
12664 First as-yet-unassigned txid. All txids greater than or equal to this
12665 are not yet started as of the time of the snapshot, and thus invisible.
12670 <entry><type>xip_list</type></entry>
12672 Active txids at the time of the snapshot. The list
12673 includes only those active txids between <literal>xmin</>
12674 and <literal>xmax</>; there might be active txids higher
12675 than <literal>xmax</>. A txid that is <literal>xmin <= txid <
12676 xmax</literal> and not in this list was already completed
12677 at the time of the snapshot, and thus either visible or
12678 dead according to its commit status. The list does not
12679 include txids of subtransactions.
12688 <type>txid_snapshot</>'s textual representation is
12689 <literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
12690 For example <literal>10:20:10,14,15</literal> means
12691 <literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
12695 <sect1 id="functions-admin
">
12696 <title>System Administration Functions</title>
12699 <xref linkend="functions-admin-set-table
"> shows the functions
12700 available to query and alter run-time configuration parameters.
12703 <table id="functions-admin-set-table
">
12704 <title>Configuration Settings Functions</title>
12707 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
12713 <literal><function>current_setting</function>(<parameter>setting_name</parameter>)</literal>
12715 <entry><type>text</type></entry>
12716 <entry>get current value of setting</entry>
12720 <literal><function>set_config(<parameter>setting_name</parameter>,
12721 <parameter>new_value</parameter>,
12722 <parameter>is_local</parameter>)</function></literal>
12724 <entry><type>text</type></entry>
12725 <entry>set parameter and return new value</entry>
12732 <primary>SET</primary>
12736 <primary>SHOW</primary>
12740 <primary>configuration</primary>
12741 <secondary sortas="server
">of the server</secondary>
12742 <tertiary>functions</tertiary>
12746 The function <function>current_setting</function> yields the
12747 current value of the setting <parameter>setting_name</parameter>.
12748 It corresponds to the <acronym>SQL</acronym> command
12749 <command>SHOW</command>. An example:
12751 SELECT current_setting('datestyle');
12761 <function>set_config</function> sets the parameter
12762 <parameter>setting_name</parameter> to
12763 <parameter>new_value</parameter>. If
12764 <parameter>is_local</parameter> is <literal>true</literal>, the
12765 new value will only apply to the current transaction. If you want
12766 the new value to apply for the current session, use
12767 <literal>false</literal> instead. The function corresponds to the
12768 SQL command <command>SET</command>. An example:
12770 SELECT set_config('log_statement_stats', 'off', false);
12780 <primary>pg_cancel_backend</primary>
12783 <primary>pg_terminate_backend</primary>
12786 <primary>pg_reload_conf</primary>
12789 <primary>pg_rotate_logfile</primary>
12793 <primary>signal</primary>
12794 <secondary sortas="backend
">backend processes</secondary>
12798 The functions shown in <xref
12799 linkend="functions-admin-signal-table
"> send control signals to
12800 other server processes. Use of these functions is restricted
12804 <table id="functions-admin-signal-table
">
12805 <title>Server Signalling Functions</title>
12808 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12815 <literal><function>pg_cancel_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12817 <entry><type>boolean</type></entry>
12818 <entry>Cancel a backend's current query</entry>
12822 <literal><function>pg_terminate_backend</function>(<parameter>pid</parameter> <type>int</>)</literal>
12824 <entry><type>boolean</type></entry>
12825 <entry>Terminate a backend</entry>
12829 <literal><function>pg_reload_conf</function>()</literal>
12831 <entry><type>boolean</type></entry>
12832 <entry>Cause server processes to reload their configuration files</entry>
12836 <literal><function>pg_rotate_logfile</function>()</literal>
12838 <entry><type>boolean</type></entry>
12839 <entry>Rotate server's log file</entry>
12846 Each of these functions returns <literal>true</literal> if
12847 successful and <literal>false</literal> otherwise.
12851 <function>pg_cancel_backend</> and <function>pg_terminate_backend</>
12852 send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
12853 respectively) to backend processes identified by process ID.
12854 The process ID of an active backend can be found from
12855 the <structfield>procpid</structfield> column of the
12856 <structname>pg_stat_activity</structname> view, or by listing the
12857 <command>postgres</command> processes on the server (using
12858 <application>ps</> on Unix or the <application>Task
12859 Manager</> on <productname>Windows</>).
12863 <function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
12864 to the server, causing configuration files
12865 to be reloaded by all server processes.
12869 <function>pg_rotate_logfile</> signals the log-file manager to switch
12870 to a new output file immediately. This works only when the built-in
12871 log collector is running, since otherwise there is no log-file manager
12876 <primary>pg_start_backup</primary>
12879 <primary>pg_stop_backup</primary>
12882 <primary>pg_switch_xlog</primary>
12885 <primary>pg_current_xlog_location</primary>
12888 <primary>pg_current_xlog_insert_location</primary>
12891 <primary>pg_xlogfile_name_offset</primary>
12894 <primary>pg_xlogfile_name</primary>
12897 <primary>backup</primary>
12901 The functions shown in <xref
12902 linkend="functions-admin-backup-table
"> assist in making on-line backups.
12903 Use of the first three functions is restricted to superusers.
12906 <table id="functions-admin-backup-table
">
12907 <title>Backup Control Functions</title>
12910 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
12917 <literal><function>pg_start_backup</function>(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</literal>
12919 <entry><type>text</type></entry>
12920 <entry>Prepare for performing on-line backup</entry>
12924 <literal><function>pg_stop_backup</function>()</literal>
12926 <entry><type>text</type></entry>
12927 <entry>Finish performing on-line backup</entry>
12931 <literal><function>pg_switch_xlog</function>()</literal>
12933 <entry><type>text</type></entry>
12934 <entry>Force switch to a new transaction log file</entry>
12938 <literal><function>pg_current_xlog_location</function>()</literal>
12940 <entry><type>text</type></entry>
12941 <entry>Get current transaction log write location</entry>
12945 <literal><function>pg_current_xlog_insert_location</function>()</literal>
12947 <entry><type>text</type></entry>
12948 <entry>Get current transaction log insert location</entry>
12952 <literal><function>pg_xlogfile_name_offset</function>(<parameter>location</> <type>text</>)</literal>
12954 <entry><type>text</>, <type>integer</></entry>
12955 <entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
12959 <literal><function>pg_xlogfile_name</function>(<parameter>location</> <type>text</>)</literal>
12961 <entry><type>text</type></entry>
12962 <entry>Convert transaction log location string to file name</entry>
12969 <function>pg_start_backup</> accepts an
12970 arbitrary user-defined label for the backup. (Typically this would be
12971 the name under which the backup dump file will be stored.) The function
12972 writes a backup label file (<filename>backup_label</>) into the
12973 database cluster's data directory, performs a checkpoint,
12974 and then returns the backup's starting transaction log location as text.
12975 The user can ignore this result value, but it is
12976 provided in case it is useful.
12978 postgres=# select pg_start_backup('label_goes_here');
12984 There is an optional boolean second parameter. If <literal>true</>,
12985 it specifies executing <function>pg_start_backup</> as quickly as
12986 possible. This forces an immediate checkpoint which will cause a
12987 spike in I/O operations, slowing any concurrently executing queries.
12991 <function>pg_stop_backup</> removes the label file created by
12992 <function>pg_start_backup</>, and creates a backup history file in
12993 the transaction log archive area. The history file includes the label given to
12994 <function>pg_start_backup</>, the starting and ending transaction log locations for
12995 the backup, and the starting and ending times of the backup. The return
12996 value is the backup's ending transaction log location (which again
12997 can be ignored). After recording the ending location, the current
12998 transaction log insertion
12999 point is automatically advanced to the next transaction log file, so that the
13000 ending transaction log file can be archived immediately to complete the backup.
13004 <function>pg_switch_xlog</> moves to the next transaction log file, allowing the
13005 current file to be archived (assuming you are using continuous archiving).
13006 The return value is the ending transaction log location + 1 within the just-completed transaction log file.
13007 If there has been no transaction log activity since the last transaction log switch,
13008 <function>pg_switch_xlog</> does nothing and returns the start location
13009 of the transaction log file currently in use.
13013 <function>pg_current_xlog_location</> displays the current transaction log write
13014 location in the same format used by the above functions. Similarly,
13015 <function>pg_current_xlog_insert_location</> displays the current transaction log
13016 insertion point. The insertion point is the <quote>logical</> end
13017 of the transaction log
13018 at any instant, while the write location is the end of what has actually
13019 been written out from the server's internal buffers. The write location
13020 is the end of what can be examined from outside the server, and is usually
13021 what you want if you are interested in archiving partially-complete transaction log
13022 files. The insertion point is made available primarily for server
13023 debugging purposes. These are both read-only operations and do not
13024 require superuser permissions.
13028 You can use <function>pg_xlogfile_name_offset</> to extract the
13029 corresponding transaction log file name and byte offset from the results of any of the
13030 above functions. For example:
13032 postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
13033 file_name | file_offset
13034 --------------------------+-------------
13035 00000001000000000000000D | 4039624
13038 Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
13039 When the given transaction log location is exactly at a transaction log file boundary, both
13040 these functions return the name of the preceding transaction log file.
13041 This is usually the desired behavior for managing transaction log archiving
13042 behavior, since the preceding file is the last one that currently
13043 needs to be archived.
13047 For details about proper usage of these functions, see
13048 <xref linkend="continuous-archiving
">.
13052 The functions shown in <xref linkend="functions-admin-dbsize
"> calculate
13053 the disk space usage of database objects.
13057 <primary>pg_column_size</primary>
13060 <primary>pg_database_size</primary>
13063 <primary>pg_relation_size</primary>
13066 <primary>pg_size_pretty</primary>
13069 <primary>pg_tablespace_size</primary>
13072 <primary>pg_total_relation_size</primary>
13075 <table id="functions-admin-dbsize
">
13076 <title>Database Object Size Functions</title>
13079 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13085 <entry><literal><function>pg_column_size</function>(<type>any</type>)</literal></entry>
13086 <entry><type>int</type></entry>
13087 <entry>Number of bytes used to store a particular value (possibly compressed)</entry>
13091 <literal><function>pg_database_size</function>(<type>oid</type>)</literal>
13093 <entry><type>bigint</type></entry>
13094 <entry>Disk space used by the database with the specified OID</entry>
13098 <literal><function>pg_database_size</function>(<type>name</type>)</literal>
13100 <entry><type>bigint</type></entry>
13101 <entry>Disk space used by the database with the specified name</entry>
13105 <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</literal>
13107 <entry><type>bigint</type></entry>
13109 Disk space used by the specified fork (<literal>'main'</literal>,
13110 <literal>'fsm'</literal> or <literal>'vm'</>)
13111 of the table or index with the specified OID or name
13116 <literal><function>pg_relation_size</function>(<parameter>relation</parameter> <type>regclass</type>)</literal>
13118 <entry><type>bigint</type></entry>
13120 Shorthand for <literal>pg_relation_size(..., 'main')</literal>
13125 <literal><function>pg_size_pretty</function>(<type>bigint</type>)</literal>
13127 <entry><type>text</type></entry>
13128 <entry>Converts a size in bytes into a human-readable format with size units</entry>
13132 <literal><function>pg_tablespace_size</function>(<type>oid</type>)</literal>
13134 <entry><type>bigint</type></entry>
13135 <entry>Disk space used by the tablespace with the specified OID</entry>
13139 <literal><function>pg_tablespace_size</function>(<type>name</type>)</literal>
13141 <entry><type>bigint</type></entry>
13142 <entry>Disk space used by the tablespace with the specified name</entry>
13146 <literal><function>pg_total_relation_size</function>(<type>regclass</type>)</literal>
13148 <entry><type>bigint</type></entry>
13150 Total disk space used by the table with the specified OID or name,
13151 including indexes and <acronym>TOAST</> data
13159 <function>pg_column_size</> shows the space used to store any individual
13164 <function>pg_database_size</function> and <function>pg_tablespace_size</>
13165 accept the OID or name of a database or tablespace, and return the total
13166 disk space used therein.
13170 <function>pg_relation_size</> accepts the OID or name of a table, index or
13171 toast table, and returns the size in bytes. Specifying
13172 <literal>'main'</literal> or leaving out the second argument returns the
13173 size of the main data fork of the relation. Specifying
13174 <literal>'fsm'</literal> returns the size of the
13175 Free Space Map (see <xref linkend="storage-fsm
">) associated with the
13176 relation. Specifying <literal>'vm'</literal> returns the size of the
13177 Visibility Map (see <xref linkend="storage-vm
">) associated with the
13182 <function>pg_size_pretty</> can be used to format the result of one of
13183 the other functions in a human-readable way, using kB, MB, GB or TB as
13188 <function>pg_total_relation_size</> accepts the OID or name of a
13189 table or toast table, and returns the size in bytes of the data
13190 and all associated indexes and toast tables.
13194 The functions shown in <xref
13195 linkend="functions-admin-genfile
"> provide native access to
13196 files on the machine hosting the server. Only files within the
13197 database cluster directory and the <varname>log_directory</> can be
13198 accessed. Use a relative path for files in the cluster directory,
13199 and a path matching the <varname>log_directory</> configuration setting
13200 for log files. Use of these functions is restricted to superusers.
13203 <table id="functions-admin-genfile
">
13204 <title>Generic File Access Functions</title>
13207 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13214 <literal><function>pg_ls_dir</function>(<parameter>dirname</> <type>text</>)</literal>
13216 <entry><type>setof text</type></entry>
13217 <entry>List the contents of a directory</entry>
13221 <literal><function>pg_read_file</function>(<parameter>filename</> <type>text</>, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>)</literal>
13223 <entry><type>text</type></entry>
13224 <entry>Return the contents of a text file</entry>
13228 <literal><function>pg_stat_file</function>(<parameter>filename</> <type>text</>)</literal>
13230 <entry><type>record</type></entry>
13231 <entry>Return information about a file</entry>
13238 <primary>pg_ls_dir</primary>
13241 <function>pg_ls_dir</> returns all the names in the specified
13242 directory, except the special entries <quote><literal>.</></> and
13243 <quote><literal>..</></>.
13247 <primary>pg_read_file</primary>
13250 <function>pg_read_file</> returns part of a text file, starting
13251 at the given <parameter>offset</>, returning at most <parameter>length</>
13252 bytes (less if the end of file is reached first). If <parameter>offset</>
13253 is negative, it is relative to the end of the file.
13257 <primary>pg_stat_file</primary>
13260 <function>pg_stat_file</> returns a record containing the file
13261 size, last accessed time stamp, last modified time stamp,
13262 last file status change time stamp (Unix platforms only),
13263 file creation time stamp (Windows only), and a <type>boolean</type>
13264 indicating if it is a directory. Typical usages include:
13266 SELECT * FROM pg_stat_file('filename');
13267 SELECT (pg_stat_file('filename')).modification;
13272 The functions shown in <xref linkend="functions-advisory-locks
"> manage
13273 advisory locks. For details about proper use of these functions, see
13274 <xref linkend="advisory-locks
">.
13277 <table id="functions-advisory-locks
">
13278 <title>Advisory Lock Functions</title>
13281 <row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
13288 <literal><function>pg_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
13290 <entry><type>void</type></entry>
13291 <entry>Obtain exclusive advisory lock</entry>
13295 <literal><function>pg_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13297 <entry><type>void</type></entry>
13298 <entry>Obtain exclusive advisory lock</entry>
13303 <literal><function>pg_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13305 <entry><type>void</type></entry>
13306 <entry>Obtain shared advisory lock</entry>
13310 <literal><function>pg_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13312 <entry><type>void</type></entry>
13313 <entry>Obtain shared advisory lock</entry>
13318 <literal><function>pg_try_advisory_lock</function>(<parameter>key</> <type>bigint</>)</literal>
13320 <entry><type>boolean</type></entry>
13321 <entry>Obtain exclusive advisory lock if available</entry>
13325 <literal><function>pg_try_advisory_lock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13327 <entry><type>boolean</type></entry>
13328 <entry>Obtain exclusive advisory lock if available</entry>
13333 <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13335 <entry><type>boolean</type></entry>
13336 <entry>Obtain shared advisory lock if available</entry>
13340 <literal><function>pg_try_advisory_lock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13342 <entry><type>boolean</type></entry>
13343 <entry>Obtain shared advisory lock if available</entry>
13348 <literal><function>pg_advisory_unlock</function>(<parameter>key</> <type>bigint</>)</literal>
13350 <entry><type>boolean</type></entry>
13351 <entry>Release an exclusive advisory lock</entry>
13355 <literal><function>pg_advisory_unlock</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13357 <entry><type>boolean</type></entry>
13358 <entry>Release an exclusive advisory lock</entry>
13363 <literal><function>pg_advisory_unlock_shared</function>(<parameter>key</> <type>bigint</>)</literal>
13365 <entry><type>boolean</type></entry>
13366 <entry>Release a shared advisory lock</entry>
13370 <literal><function>pg_advisory_unlock_shared</function>(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</literal>
13372 <entry><type>boolean</type></entry>
13373 <entry>Release a shared advisory lock</entry>
13378 <literal><function>pg_advisory_unlock_all</function>()</literal>
13380 <entry><type>void</type></entry>
13381 <entry>Release all advisory locks held by the current session</entry>
13389 <primary>pg_advisory_lock</primary>
13392 <function>pg_advisory_lock</> locks an application-defined resource,
13393 which can be identified either by a single 64-bit key value or two
13394 32-bit key values (note that these two key spaces do not overlap).
13395 The key type is specified in <literal>pg_locks.objid</>. If
13396 another session already holds a lock on the same resource, the
13397 function will wait until the resource becomes available. The lock
13398 is exclusive. Multiple lock requests stack, so that if the same resource
13399 is locked three times it must be also unlocked three times to be
13400 released for other sessions' use.
13404 <primary>pg_advisory_lock_shared</primary>
13407 <function>pg_advisory_lock_shared</> works the same as
13408 <function>pg_advisory_lock</>,
13409 except the lock can be shared with other sessions requesting shared locks.
13410 Only would-be exclusive lockers are locked out.
13414 <primary>pg_try_advisory_lock</primary>
13417 <function>pg_try_advisory_lock</> is similar to
13418 <function>pg_advisory_lock</>, except the function will not wait for the
13419 lock to become available. It will either obtain the lock immediately and
13420 return <literal>true</>, or return <literal>false</> if the lock cannot be
13421 acquired immediately.
13425 <primary>pg_try_advisory_lock_shared</primary>
13428 <function>pg_try_advisory_lock_shared</> works the same as
13429 <function>pg_try_advisory_lock</>, except it attempts to acquire
13430 a shared rather than an exclusive lock.
13434 <primary>pg_advisory_unlock</primary>
13437 <function>pg_advisory_unlock</> will release a previously-acquired
13438 exclusive advisory lock. It
13439 returns <literal>true</> if the lock is successfully released.
13440 If the lock was not held, it will return <literal>false</>,
13441 and in addition, an SQL warning will be raised by the server.
13445 <primary>pg_advisory_unlock_shared</primary>
13448 <function>pg_advisory_unlock_shared</> works the same as
13449 <function>pg_advisory_unlock</>,
13450 except it releases a shared advisory lock.
13454 <primary>pg_advisory_unlock_all</primary>
13457 <function>pg_advisory_unlock_all</> will release all advisory locks
13458 held by the current session. (This function is implicitly invoked
13459 at session end, even if the client disconnects ungracefully.)
13464 <sect1 id="functions-trigger
">
13465 <title>Trigger Functions</title>
13468 <primary>suppress_redundant_updates_trigger</primary>
13472 Currently <productname>PostgreSQL</> provides one built in trigger
13473 function, <function>suppress_redundant_updates_trigger</>,
13474 which will prevent any update
13475 that does not actually change the data in the row from taking place, in
13476 contrast to the normal behaviour which always performs the update
13477 regardless of whether or not the data has changed. (This normal behaviour
13478 makes updates run faster, since no checking is required, and is also
13479 useful in certain cases.)
13483 Ideally, you should normally avoid running updates that don't actually
13484 change the data in the record. Redundant updates can cost considerable
13485 unnecessary time, especially if there are lots of indexes to alter,
13486 and space in dead rows that will eventually have to be vacuumed.
13487 However, detecting such situations in client code is not
13488 always easy, or even possible, and writing expressions to detect
13489 them can be error-prone. An alternative is to use
13490 <function>suppress_redundant_updates_trigger</>, which will skip
13491 updates that don't change the data. You should use this with care,
13492 however. The trigger takes a small but non-trivial time for each record,
13493 so if most of the records affected by an update are actually changed,
13494 use of this trigger will actually make the update run slower.
13498 The <function>suppress_redundant_updates_trigger</> function can be
13499 added to a table like this:
13501 CREATE TRIGGER z_min_update
13502 BEFORE UPDATE ON tablename
13503 FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
13505 In most cases, you would want to fire this trigger last for each row.
13506 Bearing in mind that triggers fire in name order, you would then
13507 choose a trigger name that comes after the name of any other trigger
13508 you might have on the table.
13511 For more information about creating triggers, see
13512 <xref linkend="SQL-CREATETRIGGER
">.