14996 lines
519 KiB
Plaintext
14996 lines
519 KiB
Plaintext
<!-- doc/src/sgml/func.sgml -->
|
|
|
|
<chapter id="functions">
|
|
<title>Functions and Operators</title>
|
|
|
|
<indexterm zone="functions">
|
|
<primary>function</primary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="functions">
|
|
<primary>operator</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> provides a large number of
|
|
functions and operators for the built-in data types. Users can also
|
|
define their own functions and operators, as described in
|
|
<xref linkend="server-programming">. The
|
|
<application>psql</application> commands <command>\df</command> and
|
|
<command>\do</command> can be used to list all
|
|
available functions and operators, respectively.
|
|
</para>
|
|
|
|
<para>
|
|
If you are concerned about portability then note that most of
|
|
the functions and operators described in this chapter, with the
|
|
exception of the most trivial arithmetic and comparison operators
|
|
and some explicitly marked functions, are not specified by the
|
|
<acronym>SQL</acronym> standard. Some of this extended functionality
|
|
is present in other <acronym>SQL</acronym> database management
|
|
systems, and in many cases this functionality is compatible and
|
|
consistent between the various implementations. This chapter is also
|
|
not exhaustive; additional functions appear in relevant sections of
|
|
the manual.
|
|
</para>
|
|
|
|
|
|
<sect1 id="functions-logical">
|
|
<title>Logical Operators</title>
|
|
|
|
<indexterm zone="functions-logical">
|
|
<primary>operator</primary>
|
|
<secondary>logical</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>Boolean</primary>
|
|
<secondary>operators</secondary>
|
|
<see>operators, logical</see>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The usual logical operators are available:
|
|
|
|
<indexterm>
|
|
<primary>AND (operator)</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>OR (operator)</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>NOT (operator)</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>conjunction</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>disjunction</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>negation</primary>
|
|
</indexterm>
|
|
|
|
<simplelist>
|
|
<member><literal>AND</></member>
|
|
<member><literal>OR</></member>
|
|
<member><literal>NOT</></member>
|
|
</simplelist>
|
|
|
|
<acronym>SQL</acronym> uses a three-valued Boolean logic where the null value represents
|
|
<quote>unknown</quote>. Observe the following truth tables:
|
|
|
|
<informaltable>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry><replaceable>a</replaceable></entry>
|
|
<entry><replaceable>b</replaceable></entry>
|
|
<entry><replaceable>a</replaceable> AND <replaceable>b</replaceable></entry>
|
|
<entry><replaceable>a</replaceable> OR <replaceable>b</replaceable></entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>TRUE</entry>
|
|
<entry>TRUE</entry>
|
|
<entry>TRUE</entry>
|
|
<entry>TRUE</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>TRUE</entry>
|
|
<entry>FALSE</entry>
|
|
<entry>FALSE</entry>
|
|
<entry>TRUE</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>TRUE</entry>
|
|
<entry>NULL</entry>
|
|
<entry>NULL</entry>
|
|
<entry>TRUE</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>FALSE</entry>
|
|
<entry>FALSE</entry>
|
|
<entry>FALSE</entry>
|
|
<entry>FALSE</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>FALSE</entry>
|
|
<entry>NULL</entry>
|
|
<entry>FALSE</entry>
|
|
<entry>NULL</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>NULL</entry>
|
|
<entry>NULL</entry>
|
|
<entry>NULL</entry>
|
|
<entry>NULL</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</informaltable>
|
|
|
|
<informaltable>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry><replaceable>a</replaceable></entry>
|
|
<entry>NOT <replaceable>a</replaceable></entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>TRUE</entry>
|
|
<entry>FALSE</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>FALSE</entry>
|
|
<entry>TRUE</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>NULL</entry>
|
|
<entry>NULL</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</informaltable>
|
|
</para>
|
|
|
|
<para>
|
|
The operators <literal>AND</literal> and <literal>OR</literal> are
|
|
commutative, that is, you can switch the left and right operand
|
|
without affecting the result. But see <xref
|
|
linkend="syntax-express-eval"> for more information about the
|
|
order of evaluation of subexpressions.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="functions-comparison">
|
|
<title>Comparison Operators</title>
|
|
|
|
<indexterm zone="functions-comparison">
|
|
<primary>comparison</primary>
|
|
<secondary>operators</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The usual comparison operators are available, shown in <xref
|
|
linkend="functions-comparison-table">.
|
|
</para>
|
|
|
|
<table id="functions-comparison-table">
|
|
<title>Comparison Operators</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal><</literal> </entry>
|
|
<entry>less than</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>></literal> </entry>
|
|
<entry>greater than</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><=</literal> </entry>
|
|
<entry>less than or equal to</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>>=</literal> </entry>
|
|
<entry>greater than or equal to</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>=</literal> </entry>
|
|
<entry>equal</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><></literal> or <literal>!=</literal> </entry>
|
|
<entry>not equal</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
The <literal>!=</literal> operator is converted to
|
|
<literal><></literal> in the parser stage. It is not
|
|
possible to implement <literal>!=</literal> and
|
|
<literal><></literal> operators that do different things.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Comparison operators are available for all relevant data types.
|
|
All comparison operators are binary operators that
|
|
return values of type <type>boolean</type>; expressions like
|
|
<literal>1 < 2 < 3</literal> are not valid (because there is
|
|
no <literal><</literal> operator to compare a Boolean value with
|
|
<literal>3</literal>).
|
|
</para>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary>BETWEEN</primary>
|
|
</indexterm>
|
|
In addition to the comparison operators, the special
|
|
<token>BETWEEN</token> construct is available:
|
|
<synopsis>
|
|
<replaceable>a</replaceable> BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
|
|
</synopsis>
|
|
is equivalent to
|
|
<synopsis>
|
|
<replaceable>a</replaceable> >= <replaceable>x</replaceable> AND <replaceable>a</replaceable> <= <replaceable>y</replaceable>
|
|
</synopsis>
|
|
Notice that <token>BETWEEN</token> treats the endpoint values as included
|
|
in the range.
|
|
<literal>NOT BETWEEN</literal> does the opposite comparison:
|
|
<synopsis>
|
|
<replaceable>a</replaceable> NOT BETWEEN <replaceable>x</replaceable> AND <replaceable>y</replaceable>
|
|
</synopsis>
|
|
is equivalent to
|
|
<synopsis>
|
|
<replaceable>a</replaceable> < <replaceable>x</replaceable> OR <replaceable>a</replaceable> > <replaceable>y</replaceable>
|
|
</synopsis>
|
|
<indexterm>
|
|
<primary>BETWEEN SYMMETRIC</primary>
|
|
</indexterm>
|
|
<literal>BETWEEN SYMMETRIC</> is the same as <literal>BETWEEN</>
|
|
except there is no requirement that the argument to the left of
|
|
<literal>AND</> be less than or equal to the argument on the right.
|
|
If it is not, those two arguments are automatically swapped, so that
|
|
a nonempty range is always implied.
|
|
</para>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary>IS NULL</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS NOT NULL</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>ISNULL</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>NOTNULL</primary>
|
|
</indexterm>
|
|
To check whether a value is or is not null, use the constructs:
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> IS NULL
|
|
<replaceable>expression</replaceable> IS NOT NULL
|
|
</synopsis>
|
|
or the equivalent, but nonstandard, constructs:
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> ISNULL
|
|
<replaceable>expression</replaceable> NOTNULL
|
|
</synopsis>
|
|
<indexterm><primary>null value</primary><secondary>comparing</secondary></indexterm>
|
|
</para>
|
|
|
|
<para>
|
|
Do <emphasis>not</emphasis> write
|
|
<literal><replaceable>expression</replaceable> = NULL</literal>
|
|
because <literal>NULL</> is not <quote>equal to</quote>
|
|
<literal>NULL</>. (The null value represents an unknown value,
|
|
and it is not known whether two unknown values are equal.) This
|
|
behavior conforms to the SQL standard.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
Some applications might expect that
|
|
<literal><replaceable>expression</replaceable> = NULL</literal>
|
|
returns true if <replaceable>expression</replaceable> evaluates to
|
|
the null value. It is highly recommended that these applications
|
|
be modified to comply with the SQL standard. However, if that
|
|
cannot be done the <xref linkend="guc-transform-null-equals">
|
|
configuration variable is available. If it is enabled,
|
|
<productname>PostgreSQL</productname> will convert <literal>x =
|
|
NULL</literal> clauses to <literal>x IS NULL</literal>.
|
|
</para>
|
|
</tip>
|
|
|
|
<note>
|
|
<para>
|
|
If the <replaceable>expression</replaceable> is row-valued, then
|
|
<literal>IS NULL</> is true when the row expression itself is null
|
|
or when all the row's fields are null, while
|
|
<literal>IS NOT NULL</> is true when the row expression itself is non-null
|
|
and all the row's fields are non-null. Because of this behavior,
|
|
<literal>IS NULL</> and <literal>IS NOT NULL</> do not always return
|
|
inverse results for row-valued expressions, i.e., a row-valued
|
|
expression that contains both NULL and non-null values will return false
|
|
for both tests.
|
|
This definition conforms to the SQL standard, and is a change from the
|
|
inconsistent behavior exhibited by <productname>PostgreSQL</productname>
|
|
versions prior to 8.2.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary>IS DISTINCT FROM</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS NOT DISTINCT FROM</primary>
|
|
</indexterm>
|
|
Ordinary comparison operators yield null (signifying <quote>unknown</>),
|
|
not true or false, when either input is null. For example,
|
|
<literal>7 = NULL</> yields null. When this behavior is not suitable,
|
|
use the
|
|
<literal>IS <optional> NOT </> DISTINCT FROM</literal> constructs:
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> IS DISTINCT FROM <replaceable>expression</replaceable>
|
|
<replaceable>expression</replaceable> IS NOT DISTINCT FROM <replaceable>expression</replaceable>
|
|
</synopsis>
|
|
For non-null inputs, <literal>IS DISTINCT FROM</literal> is
|
|
the same as the <literal><></> operator. However, if both
|
|
inputs are null it returns false, and if only one input is
|
|
null it returns true. Similarly, <literal>IS NOT DISTINCT
|
|
FROM</literal> is identical to <literal>=</literal> for non-null
|
|
inputs, but it returns true when both inputs are null, and false when only
|
|
one input is null. Thus, these constructs effectively act as though null
|
|
were a normal data value, rather than <quote>unknown</>.
|
|
</para>
|
|
|
|
<para>
|
|
<indexterm>
|
|
<primary>IS TRUE</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS NOT TRUE</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS FALSE</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS NOT FALSE</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS UNKNOWN</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS NOT UNKNOWN</primary>
|
|
</indexterm>
|
|
Boolean values can also be tested using the constructs
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> IS TRUE
|
|
<replaceable>expression</replaceable> IS NOT TRUE
|
|
<replaceable>expression</replaceable> IS FALSE
|
|
<replaceable>expression</replaceable> IS NOT FALSE
|
|
<replaceable>expression</replaceable> IS UNKNOWN
|
|
<replaceable>expression</replaceable> IS NOT UNKNOWN
|
|
</synopsis>
|
|
These will always return true or false, never a null value, even when the
|
|
operand is null.
|
|
A null input is treated as the logical value <quote>unknown</>.
|
|
Notice that <literal>IS UNKNOWN</> and <literal>IS NOT UNKNOWN</> are
|
|
effectively the same as <literal>IS NULL</literal> and
|
|
<literal>IS NOT NULL</literal>, respectively, except that the input
|
|
expression must be of Boolean type.
|
|
</para>
|
|
|
|
<!-- IS OF does not conform to the ISO SQL behavior, so it is undocumented here
|
|
<para>
|
|
<indexterm>
|
|
<primary>IS OF</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>IS NOT OF</primary>
|
|
</indexterm>
|
|
It is possible to check the data type of an expression using the
|
|
constructs
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> IS OF (typename, ...)
|
|
<replaceable>expression</replaceable> IS NOT OF (typename, ...)
|
|
</synopsis>
|
|
They return a boolean value based on whether the expression's data
|
|
type is one of the listed data types.
|
|
</para>
|
|
-->
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-math">
|
|
<title>Mathematical Functions and Operators</title>
|
|
|
|
<para>
|
|
Mathematical operators are provided for many
|
|
<productname>PostgreSQL</productname> types. For types without
|
|
standard mathematical conventions
|
|
(e.g., date/time types) we
|
|
describe the actual behavior in subsequent sections.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-math-op-table"> shows the available mathematical operators.
|
|
</para>
|
|
|
|
<table id="functions-math-op-table">
|
|
<title>Mathematical Operators</title>
|
|
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry>addition</entry>
|
|
<entry><literal>2 + 3</literal></entry>
|
|
<entry><literal>5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry>subtraction</entry>
|
|
<entry><literal>2 - 3</literal></entry>
|
|
<entry><literal>-1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>*</literal> </entry>
|
|
<entry>multiplication</entry>
|
|
<entry><literal>2 * 3</literal></entry>
|
|
<entry><literal>6</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>/</literal> </entry>
|
|
<entry>division (integer division truncates the result)</entry>
|
|
<entry><literal>4 / 2</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>%</literal> </entry>
|
|
<entry>modulo (remainder)</entry>
|
|
<entry><literal>5 % 4</literal></entry>
|
|
<entry><literal>1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>^</literal> </entry>
|
|
<entry>exponentiation</entry>
|
|
<entry><literal>2.0 ^ 3.0</literal></entry>
|
|
<entry><literal>8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>|/</literal> </entry>
|
|
<entry>square root</entry>
|
|
<entry><literal>|/ 25.0</literal></entry>
|
|
<entry><literal>5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>||/</literal> </entry>
|
|
<entry>cube root</entry>
|
|
<entry><literal>||/ 27.0</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>!</literal> </entry>
|
|
<entry>factorial</entry>
|
|
<entry><literal>5 !</literal></entry>
|
|
<entry><literal>120</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>!!</literal> </entry>
|
|
<entry>factorial (prefix operator)</entry>
|
|
<entry><literal>!! 5</literal></entry>
|
|
<entry><literal>120</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>@</literal> </entry>
|
|
<entry>absolute value</entry>
|
|
<entry><literal>@ -5.0</literal></entry>
|
|
<entry><literal>5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>&</literal> </entry>
|
|
<entry>bitwise AND</entry>
|
|
<entry><literal>91 & 15</literal></entry>
|
|
<entry><literal>11</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>|</literal> </entry>
|
|
<entry>bitwise OR</entry>
|
|
<entry><literal>32 | 3</literal></entry>
|
|
<entry><literal>35</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>#</literal> </entry>
|
|
<entry>bitwise XOR</entry>
|
|
<entry><literal>17 # 5</literal></entry>
|
|
<entry><literal>20</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>~</literal> </entry>
|
|
<entry>bitwise NOT</entry>
|
|
<entry><literal>~1</literal></entry>
|
|
<entry><literal>-2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><<</literal> </entry>
|
|
<entry>bitwise shift left</entry>
|
|
<entry><literal>1 << 4</literal></entry>
|
|
<entry><literal>16</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>>></literal> </entry>
|
|
<entry>bitwise shift right</entry>
|
|
<entry><literal>8 >> 2</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The bitwise operators work only on integral data types, whereas
|
|
the others are available for all numeric data types. The bitwise
|
|
operators are also available for the bit
|
|
string types <type>bit</type> and <type>bit varying</type>, as
|
|
shown in <xref linkend="functions-bit-string-op-table">.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-math-func-table"> shows the available
|
|
mathematical functions. In the table, <literal>dp</literal>
|
|
indicates <type>double precision</type>. Many of these functions
|
|
are provided in multiple forms with different argument types.
|
|
Except where noted, any given form of a function returns the same
|
|
data type as its argument.
|
|
The functions working with <type>double precision</type> data are mostly
|
|
implemented on top of the host system's C library; accuracy and behavior in
|
|
boundary cases can therefore vary depending on the host system.
|
|
</para>
|
|
|
|
<table id="functions-math-func-table">
|
|
<title>Mathematical Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>abs</primary>
|
|
</indexterm>
|
|
<literal><function>abs(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>absolute value</entry>
|
|
<entry><literal>abs(-17.4)</literal></entry>
|
|
<entry><literal>17.4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>cbrt</primary>
|
|
</indexterm>
|
|
<literal><function>cbrt(<type>dp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>dp</type></entry>
|
|
<entry>cube root</entry>
|
|
<entry><literal>cbrt(27.0)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ceil</primary>
|
|
</indexterm>
|
|
<literal><function>ceil(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>smallest integer not less than argument</entry>
|
|
<entry><literal>ceil(-42.8)</literal></entry>
|
|
<entry><literal>-42</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ceiling</primary>
|
|
</indexterm>
|
|
<literal><function>ceiling(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>smallest integer not less than argument (alias for <function>ceil</function>)</entry>
|
|
<entry><literal>ceiling(-95.3)</literal></entry>
|
|
<entry><literal>-95</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>degrees</primary>
|
|
</indexterm>
|
|
<literal><function>degrees(<type>dp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>dp</type></entry>
|
|
<entry>radians to degrees</entry>
|
|
<entry><literal>degrees(0.5)</literal></entry>
|
|
<entry><literal>28.6478897565412</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>div</primary>
|
|
</indexterm>
|
|
<literal><function>div(<parameter>y</parameter> <type>numeric</>,
|
|
<parameter>x</parameter> <type>numeric</>)</function></literal>
|
|
</entry>
|
|
<entry><type>numeric</></entry>
|
|
<entry>integer quotient of <parameter>y</parameter>/<parameter>x</parameter></entry>
|
|
<entry><literal>div(9,4)</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>exp</primary>
|
|
</indexterm>
|
|
<literal><function>exp(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>exponential</entry>
|
|
<entry><literal>exp(1.0)</literal></entry>
|
|
<entry><literal>2.71828182845905</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>floor</primary>
|
|
</indexterm>
|
|
<literal><function>floor(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>largest integer not greater than argument</entry>
|
|
<entry><literal>floor(-42.8)</literal></entry>
|
|
<entry><literal>-43</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ln</primary>
|
|
</indexterm>
|
|
<literal><function>ln(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>natural logarithm</entry>
|
|
<entry><literal>ln(2.0)</literal></entry>
|
|
<entry><literal>0.693147180559945</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>log</primary>
|
|
</indexterm>
|
|
<literal><function>log(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>base 10 logarithm</entry>
|
|
<entry><literal>log(100.0)</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>log(<parameter>b</parameter> <type>numeric</type>,
|
|
<parameter>x</parameter> <type>numeric</type>)</function></literal></entry>
|
|
<entry><type>numeric</type></entry>
|
|
<entry>logarithm to base <parameter>b</parameter></entry>
|
|
<entry><literal>log(2.0, 64.0)</literal></entry>
|
|
<entry><literal>6.0000000000</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>mod</primary>
|
|
</indexterm>
|
|
<literal><function>mod(<parameter>y</parameter>,
|
|
<parameter>x</parameter>)</function></literal>
|
|
</entry>
|
|
<entry>(same as argument types)</entry>
|
|
<entry>remainder of <parameter>y</parameter>/<parameter>x</parameter></entry>
|
|
<entry><literal>mod(9,4)</literal></entry>
|
|
<entry><literal>1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pi</primary>
|
|
</indexterm>
|
|
<literal><function>pi()</function></literal>
|
|
</entry>
|
|
<entry><type>dp</type></entry>
|
|
<entry><quote>π</quote> constant</entry>
|
|
<entry><literal>pi()</literal></entry>
|
|
<entry><literal>3.14159265358979</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>power</primary>
|
|
</indexterm>
|
|
<literal><function>power(<parameter>a</parameter> <type>dp</type>,
|
|
<parameter>b</parameter> <type>dp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>dp</type></entry>
|
|
<entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
|
|
<entry><literal>power(9.0, 3.0)</literal></entry>
|
|
<entry><literal>729</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>power(<parameter>a</parameter> <type>numeric</type>,
|
|
<parameter>b</parameter> <type>numeric</type>)</function></literal></entry>
|
|
<entry><type>numeric</type></entry>
|
|
<entry><parameter>a</> raised to the power of <parameter>b</parameter></entry>
|
|
<entry><literal>power(9.0, 3.0)</literal></entry>
|
|
<entry><literal>729</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>radians</primary>
|
|
</indexterm>
|
|
<literal><function>radians(<type>dp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>dp</type></entry>
|
|
<entry>degrees to radians</entry>
|
|
<entry><literal>radians(45.0)</literal></entry>
|
|
<entry><literal>0.785398163397448</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>random</primary>
|
|
</indexterm>
|
|
<literal><function>random()</function></literal>
|
|
</entry>
|
|
<entry><type>dp</type></entry>
|
|
<entry>random value in the range 0.0 <= x < 1.0</entry>
|
|
<entry><literal>random()</literal></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>round</primary>
|
|
</indexterm>
|
|
<literal><function>round(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>round to nearest integer</entry>
|
|
<entry><literal>round(42.4)</literal></entry>
|
|
<entry><literal>42</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>round(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
|
|
<entry><type>numeric</type></entry>
|
|
<entry>round to <parameter>s</parameter> decimal places</entry>
|
|
<entry><literal>round(42.4382, 2)</literal></entry>
|
|
<entry><literal>42.44</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>setseed</primary>
|
|
</indexterm>
|
|
<literal><function>setseed(<type>dp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>set seed for subsequent <literal>random()</literal> calls (value between -1.0 and
|
|
1.0, inclusive)</entry>
|
|
<entry><literal>setseed(0.54823)</literal></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sign</primary>
|
|
</indexterm>
|
|
<literal><function>sign(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>sign of the argument (-1, 0, +1)</entry>
|
|
<entry><literal>sign(-8.4)</literal></entry>
|
|
<entry><literal>-1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sqrt</primary>
|
|
</indexterm>
|
|
<literal><function>sqrt(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>square root</entry>
|
|
<entry><literal>sqrt(2.0)</literal></entry>
|
|
<entry><literal>1.4142135623731</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>trunc</primary>
|
|
</indexterm>
|
|
<literal><function>trunc(<type>dp</type> or <type>numeric</type>)</function></literal>
|
|
</entry>
|
|
<entry>(same as input)</entry>
|
|
<entry>truncate toward zero</entry>
|
|
<entry><literal>trunc(42.8)</literal></entry>
|
|
<entry><literal>42</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>trunc(<parameter>v</parameter> <type>numeric</type>, <parameter>s</parameter> <type>int</type>)</function></literal></entry>
|
|
<entry><type>numeric</type></entry>
|
|
<entry>truncate to <parameter>s</parameter> decimal places</entry>
|
|
<entry><literal>trunc(42.4382, 2)</literal></entry>
|
|
<entry><literal>42.43</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>width_bucket</primary>
|
|
</indexterm>
|
|
<literal><function>width_bucket(<parameter>op</parameter> <type>numeric</type>, <parameter>b1</parameter> <type>numeric</type>, <parameter>b2</parameter> <type>numeric</type>, <parameter>count</parameter> <type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>return the bucket to which <parameter>operand</> would
|
|
be assigned in an equidepth histogram with <parameter>count</>
|
|
buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
|
|
<entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>width_bucket(<parameter>op</parameter> <type>dp</type>, <parameter>b1</parameter> <type>dp</type>, <parameter>b2</parameter> <type>dp</type>, <parameter>count</parameter> <type>int</type>)</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>return the bucket to which <parameter>operand</> would
|
|
be assigned in an equidepth histogram with <parameter>count</>
|
|
buckets, in the range <parameter>b1</> to <parameter>b2</></entry>
|
|
<entry><literal>width_bucket(5.35, 0.024, 10.06, 5)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Finally, <xref linkend="functions-math-trig-table"> shows the
|
|
available trigonometric functions. All trigonometric functions
|
|
take arguments and return values of type <type>double
|
|
precision</type>. Trigonometric functions arguments are expressed
|
|
in radians. Inverse functions return values are expressed in
|
|
radians. See unit transformation functions
|
|
<literal><function>radians()</function></literal> and
|
|
<literal><function>degrees()</function></literal> above.
|
|
</para>
|
|
|
|
<table id="functions-math-trig-table">
|
|
<title>Trigonometric Functions</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>acos</primary>
|
|
</indexterm><literal><function>acos(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>inverse cosine</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>asin</primary>
|
|
</indexterm>
|
|
<literal><function>asin(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>inverse sine</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>atan</primary>
|
|
</indexterm>
|
|
<literal><function>atan(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>inverse tangent</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>atan2</primary>
|
|
</indexterm>
|
|
<literal><function>atan2(<replaceable>y</replaceable>,
|
|
<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>inverse tangent of
|
|
<literal><replaceable>y</replaceable>/<replaceable>x</replaceable></literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>cos</primary>
|
|
</indexterm>
|
|
<literal><function>cos(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>cosine</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>cot</primary>
|
|
</indexterm>
|
|
<literal><function>cot(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>cotangent</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sin</primary>
|
|
</indexterm>
|
|
<literal><function>sin(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>sine</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>tan</primary>
|
|
</indexterm>
|
|
<literal><function>tan(<replaceable>x</replaceable>)</function></literal>
|
|
</entry>
|
|
<entry>tangent</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-string">
|
|
<title>String Functions and Operators</title>
|
|
|
|
<para>
|
|
This section describes functions and operators for examining and
|
|
manipulating string values. Strings in this context include values
|
|
of the types <type>character</type>, <type>character varying</type>,
|
|
and <type>text</type>. Unless otherwise noted, all
|
|
of the functions listed below work on all of these types, but be
|
|
wary of potential effects of automatic space-padding when using the
|
|
<type>character</type> type. Some functions also exist
|
|
natively for the bit-string types.
|
|
</para>
|
|
|
|
<para>
|
|
<acronym>SQL</acronym> defines some string functions that use
|
|
key words, rather than commas, to separate
|
|
arguments. Details are in
|
|
<xref linkend="functions-string-sql">.
|
|
<productname>PostgreSQL</> also provides versions of these functions
|
|
that use the regular function invocation syntax
|
|
(see <xref linkend="functions-string-other">).
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Before <productname>PostgreSQL</productname> 8.3, these functions would
|
|
silently accept values of several non-string data types as well, due to
|
|
the presence of implicit coercions from those data types to
|
|
<type>text</>. Those coercions have been removed because they frequently
|
|
caused surprising behaviors. However, the string concatenation operator
|
|
(<literal>||</>) still accepts non-string input, so long as at least one
|
|
input is of a string type, as shown in <xref
|
|
linkend="functions-string-sql">. For other cases, insert an explicit
|
|
coercion to <type>text</> if you need to duplicate the previous behavior.
|
|
</para>
|
|
</note>
|
|
|
|
<table id="functions-string-sql">
|
|
<title><acronym>SQL</acronym> String Functions and Operators</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><parameter>string</parameter> <literal>||</literal>
|
|
<parameter>string</parameter></literal></entry>
|
|
<entry> <type>text</type> </entry>
|
|
<entry>
|
|
String concatenation
|
|
<indexterm>
|
|
<primary>character string</primary>
|
|
<secondary>concatenation</secondary>
|
|
</indexterm>
|
|
</entry>
|
|
<entry><literal>'Post' || 'greSQL'</literal></entry>
|
|
<entry><literal>PostgreSQL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal><parameter>string</parameter> <literal>||</literal>
|
|
<parameter>non-string</parameter></literal>
|
|
or
|
|
<literal><parameter>non-string</parameter> <literal>||</literal>
|
|
<parameter>string</parameter></literal>
|
|
</entry>
|
|
<entry> <type>text</type> </entry>
|
|
<entry>
|
|
String concatenation with one non-string input
|
|
</entry>
|
|
<entry><literal>'Value: ' || 42</literal></entry>
|
|
<entry><literal>Value: 42</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>bit_length</primary>
|
|
</indexterm>
|
|
<literal><function>bit_length(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>Number of bits in string</entry>
|
|
<entry><literal>bit_length('jose')</literal></entry>
|
|
<entry><literal>32</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>char_length</primary>
|
|
</indexterm>
|
|
<literal><function>char_length(<parameter>string</parameter>)</function></literal> or <literal><function>character_length(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Number of characters in string
|
|
<indexterm>
|
|
<primary>character string</primary>
|
|
<secondary>length</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>length</primary>
|
|
<secondary sortas="character string">of a character string</secondary>
|
|
<see>character string, length</see>
|
|
</indexterm>
|
|
</entry>
|
|
<entry><literal>char_length('jose')</literal></entry>
|
|
<entry><literal>4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>lower</primary>
|
|
</indexterm>
|
|
<literal><function>lower(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Convert string to lower case</entry>
|
|
<entry><literal>lower('TOM')</literal></entry>
|
|
<entry><literal>tom</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>octet_length</primary>
|
|
</indexterm>
|
|
<literal><function>octet_length(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>Number of bytes in string</entry>
|
|
<entry><literal>octet_length('jose')</literal></entry>
|
|
<entry><literal>4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>overlay</primary>
|
|
</indexterm>
|
|
<literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Replace substring
|
|
</entry>
|
|
<entry><literal>overlay('Txxxxas' placing 'hom' from 2 for 4)</literal></entry>
|
|
<entry><literal>Thomas</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>position</primary>
|
|
</indexterm>
|
|
<literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>Location of specified substring</entry>
|
|
<entry><literal>position('om' in 'Thomas')</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>substring</primary>
|
|
</indexterm>
|
|
<literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Extract substring
|
|
</entry>
|
|
<entry><literal>substring('Thomas' from 2 for 3)</literal></entry>
|
|
<entry><literal>hom</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Extract substring matching POSIX regular expression. See
|
|
<xref linkend="functions-matching"> for more information on pattern
|
|
matching.
|
|
</entry>
|
|
<entry><literal>substring('Thomas' from '...$')</literal></entry>
|
|
<entry><literal>mas</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>substring(<parameter>string</parameter> from <replaceable>pattern</replaceable> for <replaceable>escape</replaceable>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Extract substring matching <acronym>SQL</acronym> regular expression.
|
|
See <xref linkend="functions-matching"> for more information on
|
|
pattern matching.
|
|
</entry>
|
|
<entry><literal>substring('Thomas' from '%#"o_a#"_' for '#')</literal></entry>
|
|
<entry><literal>oma</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>trim</primary>
|
|
</indexterm>
|
|
<literal><function>trim(<optional>leading | trailing | both</optional>
|
|
<optional><parameter>characters</parameter></optional> from
|
|
<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Remove the longest string containing only the
|
|
<parameter>characters</parameter> (a space by default) from the
|
|
start/end/both ends of the <parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>trim(both 'x' from 'xTomxx')</literal></entry>
|
|
<entry><literal>Tom</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>upper</primary>
|
|
</indexterm>
|
|
<literal><function>upper(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Convert string to upper case</entry>
|
|
<entry><literal>upper('tom')</literal></entry>
|
|
<entry><literal>TOM</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Additional string manipulation functions are available and are
|
|
listed in <xref linkend="functions-string-other">. Some of them are used internally to implement the
|
|
<acronym>SQL</acronym>-standard string functions listed in <xref linkend="functions-string-sql">.
|
|
</para>
|
|
|
|
<table id="functions-string-other">
|
|
<title>Other String Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ascii</primary>
|
|
</indexterm>
|
|
<literal><function>ascii(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
<acronym>ASCII</acronym> code of the first character of the
|
|
argument. For <acronym>UTF8</acronym> returns the Unicode code
|
|
point of the character. For other multibyte encodings, the
|
|
argument must be an <acronym>ASCII</acronym> character.
|
|
</entry>
|
|
<entry><literal>ascii('x')</literal></entry>
|
|
<entry><literal>120</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>btrim</primary>
|
|
</indexterm>
|
|
<literal><function>btrim(<parameter>string</parameter> <type>text</type>
|
|
<optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Remove the longest string consisting only of characters
|
|
in <parameter>characters</parameter> (a space by default)
|
|
from the start and end of <parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>btrim('xyxtrimyyx', 'xy')</literal></entry>
|
|
<entry><literal>trim</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>chr</primary>
|
|
</indexterm>
|
|
<literal><function>chr(<type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Character with the given code. For <acronym>UTF8</acronym> the
|
|
argument is treated as a Unicode code point. For other multibyte
|
|
encodings the argument must designate an
|
|
<acronym>ASCII</acronym> character. The NULL (0) character is not
|
|
allowed because text data types cannot store such bytes.
|
|
</entry>
|
|
<entry><literal>chr(65)</literal></entry>
|
|
<entry><literal>A</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>concat</primary>
|
|
</indexterm>
|
|
<literal><function>concat(<parameter>str</parameter> <type>"any"</type>
|
|
[, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Concatenate all arguments. NULL arguments are ignored.
|
|
</entry>
|
|
<entry><literal>concat('abcde', 2, NULL, 22)</literal></entry>
|
|
<entry><literal>abcde222</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>concat_ws</primary>
|
|
</indexterm>
|
|
<literal><function>concat_ws(<parameter>sep</parameter> <type>text</type>,
|
|
<parameter>str</parameter> <type>"any"</type>
|
|
[, <parameter>str</parameter> <type>"any"</type> [, ...] ])</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Concatenate all but first arguments with separators. The first
|
|
parameter is used as a separator. NULL arguments are ignored.
|
|
</entry>
|
|
<entry><literal>concat_ws(',', 'abcde', 2, NULL, 22)</literal></entry>
|
|
<entry><literal>abcde,2,22</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>convert</primary>
|
|
</indexterm>
|
|
<literal><function>convert(<parameter>string</parameter> <type>bytea</type>,
|
|
<parameter>src_encoding</parameter> <type>name</type>,
|
|
<parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Convert string to <parameter>dest_encoding</parameter>. The
|
|
original encoding is specified by
|
|
<parameter>src_encoding</parameter>. The
|
|
<parameter>string</parameter> must be valid in this encoding.
|
|
Conversions can be defined by <command>CREATE CONVERSION</command>.
|
|
Also there are some predefined conversions. See <xref
|
|
linkend="conversion-names"> for available conversions.
|
|
</entry>
|
|
<entry><literal>convert('text_in_utf8', 'UTF8', 'LATIN1')</literal></entry>
|
|
<entry><literal>text_in_utf8</literal> represented in Latin-1
|
|
encoding (ISO 8859-1)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>convert_from</primary>
|
|
</indexterm>
|
|
<literal><function>convert_from(<parameter>string</parameter> <type>bytea</type>,
|
|
<parameter>src_encoding</parameter> <type>name</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Convert string to the database encoding. The original encoding
|
|
is specified by <parameter>src_encoding</parameter>. The
|
|
<parameter>string</parameter> must be valid in this encoding.
|
|
</entry>
|
|
<entry><literal>convert_from('text_in_utf8', 'UTF8')</literal></entry>
|
|
<entry><literal>text_in_utf8</literal> represented in the current database encoding</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>convert_to</primary>
|
|
</indexterm>
|
|
<literal><function>convert_to(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>dest_encoding</parameter> <type>name</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Convert string to <parameter>dest_encoding</parameter>.
|
|
</entry>
|
|
<entry><literal>convert_to('some text', 'UTF8')</literal></entry>
|
|
<entry><literal>some text</literal> represented in the UTF8 encoding</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>decode</primary>
|
|
</indexterm>
|
|
<literal><function>decode(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>type</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Decode binary data from <parameter>string</parameter> previously
|
|
encoded with <function>encode</>. Parameter type is same as in <function>encode</>.
|
|
</entry>
|
|
<entry><literal>decode('MTIzAAE=', 'base64')</literal></entry>
|
|
<entry><literal>123\000\001</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>encode</primary>
|
|
</indexterm>
|
|
<literal><function>encode(<parameter>data</parameter> <type>bytea</type>,
|
|
<parameter>type</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Encode binary data to different representation. Supported
|
|
types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
|
|
<literal>Escape</> merely outputs null bytes as <literal>\000</> and
|
|
doubles backslashes.
|
|
</entry>
|
|
<entry><literal>encode(E'123\\000\\001', 'base64')</literal></entry>
|
|
<entry><literal>MTIzAAE=</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>format</primary>
|
|
</indexterm>
|
|
<literal><function>format</function>(<parameter>formatstr</parameter> <type>text</type>
|
|
[, <parameter>str</parameter> <type>"any"</type> [, ...] ])</literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Format a string. This function is similar to the C function
|
|
<function>sprintf</>; but only the following conversions
|
|
are recognized: <literal>%s</literal> interpolates the corresponding
|
|
argument as a string; <literal>%I</literal> escapes its argument as
|
|
an SQL identifier; <literal>%L</literal> escapes its argument as an
|
|
SQL literal; <literal>%%</literal> outputs a literal <literal>%</>.
|
|
A conversion can reference an explicit parameter position by preceding
|
|
the conversion specifier with <literal><replaceable>n</>$</>, where
|
|
<replaceable>n</replaceable> is the argument position.
|
|
See also <xref linkend="plpgsql-quote-literal-example">.
|
|
</entry>
|
|
<entry><literal>format('Hello %s, %1$s', 'World')</literal></entry>
|
|
<entry><literal>Hello World, World</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>initcap</primary>
|
|
</indexterm>
|
|
<literal><function>initcap(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Convert the first letter of each word to upper case and the
|
|
rest to lower case. Words are sequences of alphanumeric
|
|
characters separated by non-alphanumeric characters.
|
|
</entry>
|
|
<entry><literal>initcap('hi THOMAS')</literal></entry>
|
|
<entry><literal>Hi Thomas</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>left</primary>
|
|
</indexterm>
|
|
<literal><function>left(<parameter>str</parameter> <type>text</type>,
|
|
<parameter>n</parameter> <type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Return first <replaceable>n</> characters in the string. When <replaceable>n</>
|
|
is negative, return all but last |<replaceable>n</>| characters.
|
|
</entry>
|
|
<entry><literal>left('abcde', 2)</literal></entry>
|
|
<entry><literal>ab</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>length</primary>
|
|
</indexterm>
|
|
<literal><function>length(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Number of characters in <parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>length('jose')</literal></entry>
|
|
<entry><literal>4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>length(<parameter>string</parameter><type>bytea</type>,
|
|
<parameter>encoding</parameter> <type>name</type> )</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Number of characters in <parameter>string</parameter> in the given
|
|
<parameter>encoding</parameter>. The <parameter>string</parameter>
|
|
must be valid in this encoding.
|
|
</entry>
|
|
<entry><literal>length('jose', 'UTF8')</literal></entry>
|
|
<entry><literal>4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>lpad</primary>
|
|
</indexterm>
|
|
<literal><function>lpad(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>length</parameter> <type>int</type>
|
|
<optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Fill up the <parameter>string</parameter> to length
|
|
<parameter>length</parameter> by prepending the characters
|
|
<parameter>fill</parameter> (a space by default). If the
|
|
<parameter>string</parameter> is already longer than
|
|
<parameter>length</parameter> then it is truncated (on the
|
|
right).
|
|
</entry>
|
|
<entry><literal>lpad('hi', 5, 'xy')</literal></entry>
|
|
<entry><literal>xyxhi</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ltrim</primary>
|
|
</indexterm>
|
|
<literal><function>ltrim(<parameter>string</parameter> <type>text</type>
|
|
<optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Remove the longest string containing only characters from
|
|
<parameter>characters</parameter> (a space by default) from the start of
|
|
<parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>ltrim('zzzytrim', 'xyz')</literal></entry>
|
|
<entry><literal>trim</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>md5</primary>
|
|
</indexterm>
|
|
<literal><function>md5(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Calculates the MD5 hash of <parameter>string</parameter>,
|
|
returning the result in hexadecimal
|
|
</entry>
|
|
<entry><literal>md5('abc')</literal></entry>
|
|
<entry><literal>900150983cd24fb0 d6963f7d28e17f72</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>pg_client_encoding</primary>
|
|
</indexterm>
|
|
<literal><function>pg_client_encoding()</function></literal>
|
|
</entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>
|
|
Current client encoding name
|
|
</entry>
|
|
<entry><literal>pg_client_encoding()</literal></entry>
|
|
<entry><literal>SQL_ASCII</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>quote_ident</primary>
|
|
</indexterm>
|
|
<literal><function>quote_ident(<parameter>string</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Return the given string suitably quoted to be used as an identifier
|
|
in an <acronym>SQL</acronym> statement string.
|
|
Quotes are added only if necessary (i.e., if the string contains
|
|
non-identifier characters or would be case-folded).
|
|
Embedded quotes are properly doubled.
|
|
See also <xref linkend="plpgsql-quote-literal-example">.
|
|
</entry>
|
|
<entry><literal>quote_ident('Foo bar')</literal></entry>
|
|
<entry><literal>"Foo bar"</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>quote_literal</primary>
|
|
</indexterm>
|
|
<literal><function>quote_literal(<parameter>string</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Return the given string suitably quoted to be used as a string literal
|
|
in an <acronym>SQL</acronym> statement string.
|
|
Embedded single-quotes and backslashes are properly doubled.
|
|
Note that <function>quote_literal</function> returns null on null
|
|
input; if the argument might be null,
|
|
<function>quote_nullable</function> is often more suitable.
|
|
See also <xref linkend="plpgsql-quote-literal-example">.
|
|
</entry>
|
|
<entry><literal>quote_literal('O\'Reilly')</literal></entry>
|
|
<entry><literal>'O''Reilly'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>quote_literal(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Coerce the given value to text and then quote it as a literal.
|
|
Embedded single-quotes and backslashes are properly doubled.
|
|
</entry>
|
|
<entry><literal>quote_literal(42.5)</literal></entry>
|
|
<entry><literal>'42.5'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>quote_nullable</primary>
|
|
</indexterm>
|
|
<literal><function>quote_nullable(<parameter>string</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Return the given string suitably quoted to be used as a string literal
|
|
in an <acronym>SQL</acronym> statement string; or, if the argument
|
|
is null, return <literal>NULL</>.
|
|
Embedded single-quotes and backslashes are properly doubled.
|
|
See also <xref linkend="plpgsql-quote-literal-example">.
|
|
</entry>
|
|
<entry><literal>quote_nullable(NULL)</literal></entry>
|
|
<entry><literal>NULL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>quote_nullable(<parameter>value</parameter> <type>anyelement</type>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Coerce the given value to text and then quote it as a literal;
|
|
or, if the argument is null, return <literal>NULL</>.
|
|
Embedded single-quotes and backslashes are properly doubled.
|
|
</entry>
|
|
<entry><literal>quote_nullable(42.5)</literal></entry>
|
|
<entry><literal>'42.5'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regexp_matches</primary>
|
|
</indexterm>
|
|
<literal><function>regexp_matches(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
|
|
</entry>
|
|
<entry><type>setof text[]</type></entry>
|
|
<entry>
|
|
Return all captured substrings resulting from matching a POSIX regular
|
|
expression against the <parameter>string</parameter>. See
|
|
<xref linkend="functions-posix-regexp"> for more information.
|
|
</entry>
|
|
<entry><literal>regexp_matches('foobarbequebaz', '(bar)(beque)')</literal></entry>
|
|
<entry><literal>{bar,beque}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regexp_replace</primary>
|
|
</indexterm>
|
|
<literal><function>regexp_replace(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type>, <parameter>replacement</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Replace substring(s) matching a POSIX regular expression. See
|
|
<xref linkend="functions-posix-regexp"> for more information.
|
|
</entry>
|
|
<entry><literal>regexp_replace('Thomas', '.[mN]a.', 'M')</literal></entry>
|
|
<entry><literal>ThM</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regexp_split_to_array</primary>
|
|
</indexterm>
|
|
<literal><function>regexp_split_to_array(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type> ])</function></literal>
|
|
</entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>
|
|
Split <parameter>string</parameter> using a POSIX regular expression as
|
|
the delimiter. See <xref linkend="functions-posix-regexp"> for more
|
|
information.
|
|
</entry>
|
|
<entry><literal>regexp_split_to_array('hello world', E'\\s+')</literal></entry>
|
|
<entry><literal>{hello,world}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regexp_split_to_table</primary>
|
|
</indexterm>
|
|
<literal><function>regexp_split_to_table(<parameter>string</parameter> <type>text</type>, <parameter>pattern</parameter> <type>text</type> [, <parameter>flags</parameter> <type>text</type>])</function></literal>
|
|
</entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>
|
|
Split <parameter>string</parameter> using a POSIX regular expression as
|
|
the delimiter. See <xref linkend="functions-posix-regexp"> for more
|
|
information.
|
|
</entry>
|
|
<entry><literal>regexp_split_to_table('hello world', E'\\s+')</literal></entry>
|
|
<entry><literal>hello</literal><para><literal>world</literal></para> (2 rows)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>repeat</primary>
|
|
</indexterm>
|
|
<literal><function>repeat(<parameter>string</parameter> <type>text</type>, <parameter>number</parameter> <type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Repeat <parameter>string</parameter> the specified
|
|
<parameter>number</parameter> of times</entry>
|
|
<entry><literal>repeat('Pg', 4)</literal></entry>
|
|
<entry><literal>PgPgPgPg</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>replace</primary>
|
|
</indexterm>
|
|
<literal><function>replace(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>from</parameter> <type>text</type>,
|
|
<parameter>to</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Replace all occurrences in <parameter>string</parameter> of substring
|
|
<parameter>from</parameter> with substring <parameter>to</parameter>
|
|
</entry>
|
|
<entry><literal>replace('abcdefabcdef', 'cd', 'XX')</literal></entry>
|
|
<entry><literal>abXXefabXXef</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>reverse</primary>
|
|
</indexterm>
|
|
<literal><function>reverse(<parameter>str</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Return reversed string.
|
|
</entry>
|
|
<entry><literal>reverse('abcde')</literal></entry>
|
|
<entry><literal>edcba</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>right</primary>
|
|
</indexterm>
|
|
<literal><function>right(<parameter>str</parameter> <type>text</type>,
|
|
<parameter>n</parameter> <type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Return last <replaceable>n</> characters in the string. When <replaceable>n</>
|
|
is negative, return all but first |<replaceable>n</>| characters.
|
|
</entry>
|
|
<entry><literal>right('abcde', 2)</literal></entry>
|
|
<entry><literal>de</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>rpad</primary>
|
|
</indexterm>
|
|
<literal><function>rpad(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>length</parameter> <type>int</type>
|
|
<optional>, <parameter>fill</parameter> <type>text</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Fill up the <parameter>string</parameter> to length
|
|
<parameter>length</parameter> by appending the characters
|
|
<parameter>fill</parameter> (a space by default). If the
|
|
<parameter>string</parameter> is already longer than
|
|
<parameter>length</parameter> then it is truncated.
|
|
</entry>
|
|
<entry><literal>rpad('hi', 5, 'xy')</literal></entry>
|
|
<entry><literal>hixyx</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>rtrim</primary>
|
|
</indexterm>
|
|
<literal><function>rtrim(<parameter>string</parameter> <type>text</type>
|
|
<optional>, <parameter>characters</parameter> <type>text</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Remove the longest string containing only characters from
|
|
<parameter>characters</parameter> (a space by default) from the end of
|
|
<parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>rtrim('trimxxxx', 'x')</literal></entry>
|
|
<entry><literal>trim</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>split_part</primary>
|
|
</indexterm>
|
|
<literal><function>split_part(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>delimiter</parameter> <type>text</type>,
|
|
<parameter>field</parameter> <type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Split <parameter>string</parameter> on <parameter>delimiter</parameter>
|
|
and return the given field (counting from one)
|
|
</entry>
|
|
<entry><literal>split_part('abc~@~def~@~ghi', '~@~', 2)</literal></entry>
|
|
<entry><literal>def</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>strpos</primary>
|
|
</indexterm>
|
|
<literal><function>strpos(<parameter>string</parameter>, <parameter>substring</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Location of specified substring (same as
|
|
<literal>position(<parameter>substring</parameter> in
|
|
<parameter>string</parameter>)</literal>, but note the reversed
|
|
argument order)
|
|
</entry>
|
|
<entry><literal>strpos('high', 'ig')</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>substr</primary>
|
|
</indexterm>
|
|
<literal><function>substr(<parameter>string</parameter>, <parameter>from</parameter> <optional>, <parameter>count</parameter></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Extract substring (same as
|
|
<literal>substring(<parameter>string</parameter> from <parameter>from</parameter> for <parameter>count</parameter>)</literal>)
|
|
</entry>
|
|
<entry><literal>substr('alphabet', 3, 2)</literal></entry>
|
|
<entry><literal>ph</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_ascii</primary>
|
|
</indexterm>
|
|
<literal><function>to_ascii(<parameter>string</parameter> <type>text</type>
|
|
<optional>, <parameter>encoding</parameter> <type>text</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Convert <parameter>string</parameter> to <acronym>ASCII</acronym> from another encoding
|
|
(only supports conversion from <literal>LATIN1</>, <literal>LATIN2</>, <literal>LATIN9</>,
|
|
and <literal>WIN1250</> encodings)
|
|
</entry>
|
|
<entry><literal>to_ascii('Karel')</literal></entry>
|
|
<entry><literal>Karel</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_hex</primary>
|
|
</indexterm>
|
|
<literal><function>to_hex(<parameter>number</parameter> <type>int</type>
|
|
or <type>bigint</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Convert <parameter>number</parameter> to its equivalent hexadecimal
|
|
representation
|
|
</entry>
|
|
<entry><literal>to_hex(2147483647)</literal></entry>
|
|
<entry><literal>7fffffff</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>translate</primary>
|
|
</indexterm>
|
|
<literal><function>translate(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>from</parameter> <type>text</type>,
|
|
<parameter>to</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Any character in <parameter>string</parameter> that matches a
|
|
character in the <parameter>from</parameter> set is replaced by
|
|
the corresponding character in the <parameter>to</parameter>
|
|
set. If <parameter>from</parameter> is longer than
|
|
<parameter>to</parameter>, occurrences of the extra characters in
|
|
<parameter>from</parameter> are removed.
|
|
</entry>
|
|
<entry><literal>translate('12345', '143', 'ax')</literal></entry>
|
|
<entry><literal>a2x5</literal></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
See also the aggregate function <function>string_agg</function> in
|
|
<xref linkend="functions-aggregate">.
|
|
</para>
|
|
|
|
<table id="conversion-names">
|
|
<title>Built-in Conversions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Conversion Name
|
|
<footnote>
|
|
<para>
|
|
The conversion names follow a standard naming scheme: The
|
|
official name of the source encoding with all
|
|
non-alphanumeric characters replaced by underscores, followed
|
|
by <literal>_to_</literal>, followed by the similarly processed
|
|
destination encoding name. Therefore, the names might deviate
|
|
from the customary encoding names.
|
|
</para>
|
|
</footnote>
|
|
</entry>
|
|
<entry>Source Encoding</entry>
|
|
<entry>Destination Encoding</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>ascii_to_mic</literal></entry>
|
|
<entry><literal>SQL_ASCII</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>ascii_to_utf8</literal></entry>
|
|
<entry><literal>SQL_ASCII</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>big5_to_euc_tw</literal></entry>
|
|
<entry><literal>BIG5</literal></entry>
|
|
<entry><literal>EUC_TW</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>big5_to_mic</literal></entry>
|
|
<entry><literal>BIG5</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>big5_to_utf8</literal></entry>
|
|
<entry><literal>BIG5</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_cn_to_mic</literal></entry>
|
|
<entry><literal>EUC_CN</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_cn_to_utf8</literal></entry>
|
|
<entry><literal>EUC_CN</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_jp_to_mic</literal></entry>
|
|
<entry><literal>EUC_JP</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_jp_to_sjis</literal></entry>
|
|
<entry><literal>EUC_JP</literal></entry>
|
|
<entry><literal>SJIS</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_jp_to_utf8</literal></entry>
|
|
<entry><literal>EUC_JP</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_kr_to_mic</literal></entry>
|
|
<entry><literal>EUC_KR</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_kr_to_utf8</literal></entry>
|
|
<entry><literal>EUC_KR</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_tw_to_big5</literal></entry>
|
|
<entry><literal>EUC_TW</literal></entry>
|
|
<entry><literal>BIG5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_tw_to_mic</literal></entry>
|
|
<entry><literal>EUC_TW</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_tw_to_utf8</literal></entry>
|
|
<entry><literal>EUC_TW</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>gb18030_to_utf8</literal></entry>
|
|
<entry><literal>GB18030</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>gbk_to_utf8</literal></entry>
|
|
<entry><literal>GBK</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_10_to_utf8</literal></entry>
|
|
<entry><literal>LATIN6</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_13_to_utf8</literal></entry>
|
|
<entry><literal>LATIN7</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_14_to_utf8</literal></entry>
|
|
<entry><literal>LATIN8</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_15_to_utf8</literal></entry>
|
|
<entry><literal>LATIN9</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_16_to_utf8</literal></entry>
|
|
<entry><literal>LATIN10</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_1_to_mic</literal></entry>
|
|
<entry><literal>LATIN1</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_1_to_utf8</literal></entry>
|
|
<entry><literal>LATIN1</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_2_to_mic</literal></entry>
|
|
<entry><literal>LATIN2</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_2_to_utf8</literal></entry>
|
|
<entry><literal>LATIN2</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_2_to_windows_1250</literal></entry>
|
|
<entry><literal>LATIN2</literal></entry>
|
|
<entry><literal>WIN1250</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_3_to_mic</literal></entry>
|
|
<entry><literal>LATIN3</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_3_to_utf8</literal></entry>
|
|
<entry><literal>LATIN3</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_4_to_mic</literal></entry>
|
|
<entry><literal>LATIN4</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_4_to_utf8</literal></entry>
|
|
<entry><literal>LATIN4</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_5_to_koi8_r</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_5_to_mic</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_5_to_utf8</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_5_to_windows_1251</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_5_to_windows_866</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_6_to_utf8</literal></entry>
|
|
<entry><literal>ISO_8859_6</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_7_to_utf8</literal></entry>
|
|
<entry><literal>ISO_8859_7</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_8_to_utf8</literal></entry>
|
|
<entry><literal>ISO_8859_8</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>iso_8859_9_to_utf8</literal></entry>
|
|
<entry><literal>LATIN5</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>johab_to_utf8</literal></entry>
|
|
<entry><literal>JOHAB</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>koi8_r_to_iso_8859_5</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>koi8_r_to_mic</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>koi8_r_to_utf8</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>koi8_r_to_windows_1251</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>koi8_r_to_windows_866</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>koi8_u_to_utf8</literal></entry>
|
|
<entry><literal>KOI8U</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_ascii</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>SQL_ASCII</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_big5</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>BIG5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_euc_cn</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>EUC_CN</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_euc_jp</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>EUC_JP</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_euc_kr</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>EUC_KR</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_euc_tw</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>EUC_TW</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_iso_8859_1</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>LATIN1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_iso_8859_2</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>LATIN2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_iso_8859_3</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>LATIN3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_iso_8859_4</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>LATIN4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_iso_8859_5</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_koi8_r</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_sjis</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>SJIS</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_windows_1250</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>WIN1250</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_windows_1251</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>mic_to_windows_866</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>sjis_to_euc_jp</literal></entry>
|
|
<entry><literal>SJIS</literal></entry>
|
|
<entry><literal>EUC_JP</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>sjis_to_mic</literal></entry>
|
|
<entry><literal>SJIS</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>sjis_to_utf8</literal></entry>
|
|
<entry><literal>SJIS</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>tcvn_to_utf8</literal></entry>
|
|
<entry><literal>WIN1258</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>uhc_to_utf8</literal></entry>
|
|
<entry><literal>UHC</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_ascii</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>SQL_ASCII</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_big5</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>BIG5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_euc_cn</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>EUC_CN</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_euc_jp</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>EUC_JP</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_euc_kr</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>EUC_KR</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_euc_tw</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>EUC_TW</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_gb18030</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>GB18030</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_gbk</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>GBK</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_1</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_10</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN6</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_13</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN7</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_14</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_15</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN9</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_16</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN10</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_2</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_3</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_4</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN4</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_5</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_6</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>ISO_8859_6</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_7</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>ISO_8859_7</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_8</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>ISO_8859_8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_iso_8859_9</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>LATIN5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_johab</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>JOHAB</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_koi8_r</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_koi8_u</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>KOI8U</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_sjis</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>SJIS</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_tcvn</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1258</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_uhc</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>UHC</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1250</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1250</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1251</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1252</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1252</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1253</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1253</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1254</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1254</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1255</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1255</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1256</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1256</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_1257</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN1257</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_866</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>utf8_to_windows_874</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>WIN874</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1250_to_iso_8859_2</literal></entry>
|
|
<entry><literal>WIN1250</literal></entry>
|
|
<entry><literal>LATIN2</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1250_to_mic</literal></entry>
|
|
<entry><literal>WIN1250</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1250_to_utf8</literal></entry>
|
|
<entry><literal>WIN1250</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1251_to_iso_8859_5</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1251_to_koi8_r</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1251_to_mic</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1251_to_utf8</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1251_to_windows_866</literal></entry>
|
|
<entry><literal>WIN1251</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1252_to_utf8</literal></entry>
|
|
<entry><literal>WIN1252</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_1256_to_utf8</literal></entry>
|
|
<entry><literal>WIN1256</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_866_to_iso_8859_5</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
<entry><literal>ISO_8859_5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_866_to_koi8_r</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
<entry><literal>KOI8R</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_866_to_mic</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
<entry><literal>MULE_INTERNAL</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_866_to_utf8</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_866_to_windows_1251</literal></entry>
|
|
<entry><literal>WIN866</literal></entry>
|
|
<entry><literal>WIN</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>windows_874_to_utf8</literal></entry>
|
|
<entry><literal>WIN874</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_jis_2004_to_utf8</literal></entry>
|
|
<entry><literal>EUC_JIS_2004</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>ut8_to_euc_jis_2004</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>EUC_JIS_2004</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>shift_jis_2004_to_utf8</literal></entry>
|
|
<entry><literal>SHIFT_JIS_2004</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>ut8_to_shift_jis_2004</literal></entry>
|
|
<entry><literal>UTF8</literal></entry>
|
|
<entry><literal>SHIFT_JIS_2004</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>euc_jis_2004_to_shift_jis_2004</literal></entry>
|
|
<entry><literal>EUC_JIS_2004</literal></entry>
|
|
<entry><literal>SHIFT_JIS_2004</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal>shift_jis_2004_to_euc_jis_2004</literal></entry>
|
|
<entry><literal>SHIFT_JIS_2004</literal></entry>
|
|
<entry><literal>EUC_JIS_2004</literal></entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-binarystring">
|
|
<title>Binary String Functions and Operators</title>
|
|
|
|
<indexterm zone="functions-binarystring">
|
|
<primary>binary data</primary>
|
|
<secondary>functions</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes functions and operators for examining and
|
|
manipulating values of type <type>bytea</type>.
|
|
</para>
|
|
|
|
<para>
|
|
<acronym>SQL</acronym> defines some string functions that use
|
|
key words, rather than commas, to separate
|
|
arguments. Details are in
|
|
<xref linkend="functions-binarystring-sql">.
|
|
<productname>PostgreSQL</> also provides versions of these functions
|
|
that use the regular function invocation syntax
|
|
(see <xref linkend="functions-binarystring-other">).
|
|
</para>
|
|
|
|
<table id="functions-binarystring-sql">
|
|
<title><acronym>SQL</acronym> Binary String Functions and Operators</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><parameter>string</parameter> <literal>||</literal>
|
|
<parameter>string</parameter></literal></entry>
|
|
<entry> <type>bytea</type> </entry>
|
|
<entry>
|
|
String concatenation
|
|
<indexterm>
|
|
<primary>binary string</primary>
|
|
<secondary>concatenation</secondary>
|
|
</indexterm>
|
|
</entry>
|
|
<entry><literal>E'\\\\Post'::bytea || E'\\047gres\\000'::bytea</literal></entry>
|
|
<entry><literal>\\Post'gres\000</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>octet_length</primary>
|
|
</indexterm>
|
|
<literal><function>octet_length(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>Number of bytes in binary string</entry>
|
|
<entry><literal>octet_length(E'jo\\000se'::bytea)</literal></entry>
|
|
<entry><literal>5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>overlay</primary>
|
|
</indexterm>
|
|
<literal><function>overlay(<parameter>string</parameter> placing <parameter>string</parameter> from <type>int</type> <optional>for <type>int</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Replace substring
|
|
</entry>
|
|
<entry><literal>overlay(E'Th\\000omas'::bytea placing E'\\002\\003'::bytea from 2 for 3)</literal></entry>
|
|
<entry><literal>T\\002\\003mas</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>position</primary>
|
|
</indexterm>
|
|
<literal><function>position(<parameter>substring</parameter> in <parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>Location of specified substring</entry>
|
|
<entry><literal>position(E'\\000om'::bytea in E'Th\\000omas'::bytea)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>substring</primary>
|
|
</indexterm>
|
|
<literal><function>substring(<parameter>string</parameter> <optional>from <type>int</type></optional> <optional>for <type>int</type></optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Extract substring
|
|
</entry>
|
|
<entry><literal>substring(E'Th\\000omas'::bytea from 2 for 3)</literal></entry>
|
|
<entry><literal>h\000o</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>trim</primary>
|
|
</indexterm>
|
|
<literal><function>trim(<optional>both</optional>
|
|
<parameter>bytes</parameter> from
|
|
<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Remove the longest string containing only the bytes in
|
|
<parameter>bytes</parameter> from the start
|
|
and end of <parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>trim(E'\\000'::bytea from E'\\000Tom\\000'::bytea)</literal></entry>
|
|
<entry><literal>Tom</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Additional binary string manipulation functions are available and
|
|
are listed in <xref linkend="functions-binarystring-other">. Some
|
|
of them are used internally to implement the
|
|
<acronym>SQL</acronym>-standard string functions listed in <xref
|
|
linkend="functions-binarystring-sql">.
|
|
</para>
|
|
|
|
<table id="functions-binarystring-other">
|
|
<title>Other Binary String Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>btrim</primary>
|
|
</indexterm>
|
|
<literal><function>btrim(<parameter>string</parameter>
|
|
<type>bytea</type>, <parameter>bytes</parameter> <type>bytea</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Remove the longest string consisting only of bytes
|
|
in <parameter>bytes</parameter> from the start and end of
|
|
<parameter>string</parameter>
|
|
</entry>
|
|
<entry><literal>btrim(E'\\000trim\\000'::bytea, E'\\000'::bytea)</literal></entry>
|
|
<entry><literal>trim</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>decode</primary>
|
|
</indexterm>
|
|
<literal><function>decode(<parameter>string</parameter> <type>text</type>,
|
|
<parameter>type</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Decode binary string from <parameter>string</parameter> previously
|
|
encoded with <function>encode</>. Parameter type is same as in <function>encode</>.
|
|
</entry>
|
|
<entry><literal>decode(E'123\\000456', 'escape')</literal></entry>
|
|
<entry><literal>123\000456</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>encode</primary>
|
|
</indexterm>
|
|
<literal><function>encode(<parameter>string</parameter> <type>bytea</type>,
|
|
<parameter>type</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Encode binary string to <acronym>ASCII</acronym>-only representation. Supported
|
|
types are: <literal>base64</>, <literal>hex</>, <literal>escape</>.
|
|
</entry>
|
|
<entry><literal>encode(E'123\\000456'::bytea, 'escape')</literal></entry>
|
|
<entry><literal>123\000456</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>get_bit</primary>
|
|
</indexterm>
|
|
<literal><function>get_bit(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Extract bit from string
|
|
</entry>
|
|
<entry><literal>get_bit(E'Th\\000omas'::bytea, 45)</literal></entry>
|
|
<entry><literal>1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>get_byte</primary>
|
|
</indexterm>
|
|
<literal><function>get_byte(<parameter>string</parameter>, <parameter>offset</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Extract byte from string
|
|
</entry>
|
|
<entry><literal>get_byte(E'Th\\000omas'::bytea, 4)</literal></entry>
|
|
<entry><literal>109</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>length</primary>
|
|
</indexterm>
|
|
<literal><function>length(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Length of binary string
|
|
<indexterm>
|
|
<primary>binary string</primary>
|
|
<secondary>length</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>length</primary>
|
|
<secondary sortas="binary string">of a binary string</secondary>
|
|
<see>binary strings, length</see>
|
|
</indexterm>
|
|
</entry>
|
|
<entry><literal>length(E'jo\\000se'::bytea)</literal></entry>
|
|
<entry><literal>5</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>md5</primary>
|
|
</indexterm>
|
|
<literal><function>md5(<parameter>string</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
Calculates the MD5 hash of <parameter>string</parameter>,
|
|
returning the result in hexadecimal
|
|
</entry>
|
|
<entry><literal>md5(E'Th\\000omas'::bytea)</literal></entry>
|
|
<entry><literal>8ab2d3c9689aaf18 b4958c334c82d8b1</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>set_bit</primary>
|
|
</indexterm>
|
|
<literal><function>set_bit(<parameter>string</parameter>,
|
|
<parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Set bit in string
|
|
</entry>
|
|
<entry><literal>set_bit(E'Th\\000omas'::bytea, 45, 0)</literal></entry>
|
|
<entry><literal>Th\000omAs</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>set_byte</primary>
|
|
</indexterm>
|
|
<literal><function>set_byte(<parameter>string</parameter>,
|
|
<parameter>offset</parameter>, <parameter>newvalue</>)</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>
|
|
Set byte in string
|
|
</entry>
|
|
<entry><literal>set_byte(E'Th\\000omas'::bytea, 4, 64)</literal></entry>
|
|
<entry><literal>Th\000o@as</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>get_byte</> and <function>set_byte</> number the first byte
|
|
of a binary string as byte 0.
|
|
<function>get_bit</> and <function>set_bit</> number bits from the
|
|
right within each byte; for example bit 0 is the least significant bit of
|
|
the first byte, and bit 15 is the most significant bit of the second byte.
|
|
</para>
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-bitstring">
|
|
<title>Bit String Functions and Operators</title>
|
|
|
|
<indexterm zone="functions-bitstring">
|
|
<primary>bit strings</primary>
|
|
<secondary>functions</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes functions and operators for examining and
|
|
manipulating bit strings, that is values of the types
|
|
<type>bit</type> and <type>bit varying</type>. Aside from the
|
|
usual comparison operators, the operators
|
|
shown in <xref linkend="functions-bit-string-op-table"> can be used.
|
|
Bit string operands of <literal>&</literal>, <literal>|</literal>,
|
|
and <literal>#</literal> must be of equal length. When bit
|
|
shifting, the original length of the string is preserved, as shown
|
|
in the examples.
|
|
</para>
|
|
|
|
<table id="functions-bit-string-op-table">
|
|
<title>Bit String Operators</title>
|
|
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>||</literal> </entry>
|
|
<entry>concatenation</entry>
|
|
<entry><literal>B'10001' || B'011'</literal></entry>
|
|
<entry><literal>10001011</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>&</literal> </entry>
|
|
<entry>bitwise AND</entry>
|
|
<entry><literal>B'10001' & B'01101'</literal></entry>
|
|
<entry><literal>00001</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>|</literal> </entry>
|
|
<entry>bitwise OR</entry>
|
|
<entry><literal>B'10001' | B'01101'</literal></entry>
|
|
<entry><literal>11101</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>#</literal> </entry>
|
|
<entry>bitwise XOR</entry>
|
|
<entry><literal>B'10001' # B'01101'</literal></entry>
|
|
<entry><literal>11100</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>~</literal> </entry>
|
|
<entry>bitwise NOT</entry>
|
|
<entry><literal>~ B'10001'</literal></entry>
|
|
<entry><literal>01110</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><<</literal> </entry>
|
|
<entry>bitwise shift left</entry>
|
|
<entry><literal>B'10001' << 3</literal></entry>
|
|
<entry><literal>01000</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>>></literal> </entry>
|
|
<entry>bitwise shift right</entry>
|
|
<entry><literal>B'10001' >> 2</literal></entry>
|
|
<entry><literal>00100</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The following <acronym>SQL</acronym>-standard functions work on bit
|
|
strings as well as character strings:
|
|
<literal><function>length</function></literal>,
|
|
<literal><function>bit_length</function></literal>,
|
|
<literal><function>octet_length</function></literal>,
|
|
<literal><function>position</function></literal>,
|
|
<literal><function>substring</function></literal>,
|
|
<literal><function>overlay</function></literal>.
|
|
</para>
|
|
|
|
<para>
|
|
The following functions work on bit strings as well as binary
|
|
strings:
|
|
<literal><function>get_bit</function></literal>,
|
|
<literal><function>set_bit</function></literal>.
|
|
When working with a bit string, these functions number the first
|
|
(leftmost) bit of the string as bit 0.
|
|
</para>
|
|
|
|
<para>
|
|
In addition, it is possible to cast integral values to and from type
|
|
<type>bit</>.
|
|
Some examples:
|
|
<programlisting>
|
|
44::bit(10) <lineannotation>0000101100</lineannotation>
|
|
44::bit(3) <lineannotation>100</lineannotation>
|
|
cast(-44 as bit(12)) <lineannotation>111111010100</lineannotation>
|
|
'1110'::bit(4)::integer <lineannotation>14</lineannotation>
|
|
</programlisting>
|
|
Note that casting to just <quote>bit</> means casting to
|
|
<literal>bit(1)</>, and so will deliver only the least significant
|
|
bit of the integer.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Prior to <productname>PostgreSQL</productname> 8.0, casting an
|
|
integer to <type>bit(n)</> would copy the leftmost <literal>n</>
|
|
bits of the integer, whereas now it copies the rightmost <literal>n</>
|
|
bits. Also, casting an integer to a bit string width wider than
|
|
the integer itself will sign-extend on the left.
|
|
</para>
|
|
</note>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-matching">
|
|
<title>Pattern Matching</title>
|
|
|
|
<indexterm zone="functions-matching">
|
|
<primary>pattern matching</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
There are three separate approaches to pattern matching provided
|
|
by <productname>PostgreSQL</productname>: the traditional
|
|
<acronym>SQL</acronym> <function>LIKE</function> operator, the
|
|
more recent <function>SIMILAR TO</function> operator (added in
|
|
SQL:1999), and <acronym>POSIX</acronym>-style regular
|
|
expressions. Aside from the basic <quote>does this string match
|
|
this pattern?</> operators, functions are available to extract
|
|
or replace matching substrings and to split a string at matching
|
|
locations.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
If you have pattern matching needs that go beyond this,
|
|
consider writing a user-defined function in Perl or Tcl.
|
|
</para>
|
|
</tip>
|
|
|
|
<sect2 id="functions-like">
|
|
<title><function>LIKE</function></title>
|
|
|
|
<indexterm>
|
|
<primary>LIKE</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<replaceable>string</replaceable> LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
|
|
<replaceable>string</replaceable> NOT LIKE <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>LIKE</function> expression returns true if the
|
|
<replaceable>string</replaceable> matches the supplied
|
|
<replaceable>pattern</replaceable>. (As
|
|
expected, the <function>NOT LIKE</function> expression returns
|
|
false if <function>LIKE</function> returns true, and vice versa.
|
|
An equivalent expression is
|
|
<literal>NOT (<replaceable>string</replaceable> LIKE
|
|
<replaceable>pattern</replaceable>)</literal>.)
|
|
</para>
|
|
|
|
<para>
|
|
If <replaceable>pattern</replaceable> does not contain percent
|
|
signs or underscores, then the pattern only represents the string
|
|
itself; in that case <function>LIKE</function> acts like the
|
|
equals operator. An underscore (<literal>_</literal>) in
|
|
<replaceable>pattern</replaceable> stands for (matches) any single
|
|
character; a percent sign (<literal>%</literal>) matches any sequence
|
|
of zero or more characters.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
'abc' LIKE 'abc' <lineannotation>true</lineannotation>
|
|
'abc' LIKE 'a%' <lineannotation>true</lineannotation>
|
|
'abc' LIKE '_b_' <lineannotation>true</lineannotation>
|
|
'abc' LIKE 'c' <lineannotation>false</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
<function>LIKE</function> pattern matching always covers the entire
|
|
string. Therefore, to match a sequence anywhere within a string, the
|
|
pattern must start and end with a percent sign.
|
|
</para>
|
|
|
|
<para>
|
|
To match a literal underscore or percent sign without matching
|
|
other characters, the respective character in
|
|
<replaceable>pattern</replaceable> must be
|
|
preceded by the escape character. The default escape
|
|
character is the backslash but a different one can be selected by
|
|
using the <literal>ESCAPE</literal> clause. To match the escape
|
|
character itself, write two escape characters.
|
|
</para>
|
|
|
|
<para>
|
|
Note that the backslash already has a special meaning in string literals,
|
|
so to write a pattern constant that contains a backslash you must write two
|
|
backslashes in an SQL statement (assuming escape string syntax is used, see
|
|
<xref linkend="sql-syntax-strings">). Thus, writing a pattern that
|
|
actually matches a literal backslash means writing four backslashes in the
|
|
statement. You can avoid this by selecting a different escape character
|
|
with <literal>ESCAPE</literal>; then a backslash is not special to
|
|
<function>LIKE</function> anymore. (But backslash is still special to the
|
|
string literal parser, so you still need two of them to match a backslash.)
|
|
</para>
|
|
|
|
<para>
|
|
It's also possible to select no escape character by writing
|
|
<literal>ESCAPE ''</literal>. This effectively disables the
|
|
escape mechanism, which makes it impossible to turn off the
|
|
special meaning of underscore and percent signs in the pattern.
|
|
</para>
|
|
|
|
<para>
|
|
The key word <token>ILIKE</token> can be used instead of
|
|
<token>LIKE</token> to make the match case-insensitive according
|
|
to the active locale. This is not in the <acronym>SQL</acronym> standard but is a
|
|
<productname>PostgreSQL</productname> extension.
|
|
</para>
|
|
|
|
<para>
|
|
The operator <literal>~~</literal> is equivalent to
|
|
<function>LIKE</function>, and <literal>~~*</literal> corresponds to
|
|
<function>ILIKE</function>. There are also
|
|
<literal>!~~</literal> and <literal>!~~*</literal> operators that
|
|
represent <function>NOT LIKE</function> and <function>NOT
|
|
ILIKE</function>, respectively. All of these operators are
|
|
<productname>PostgreSQL</productname>-specific.
|
|
</para>
|
|
</sect2>
|
|
|
|
|
|
<sect2 id="functions-similarto-regexp">
|
|
<title><function>SIMILAR TO</function> Regular Expressions</title>
|
|
|
|
<indexterm>
|
|
<primary>regular expression</primary>
|
|
<!-- <seealso>pattern matching</seealso> breaks index build -->
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>SIMILAR TO</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>substring</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<replaceable>string</replaceable> SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
|
|
<replaceable>string</replaceable> NOT SIMILAR TO <replaceable>pattern</replaceable> <optional>ESCAPE <replaceable>escape-character</replaceable></optional>
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>SIMILAR TO</function> operator returns true or
|
|
false depending on whether its pattern matches the given string.
|
|
It is similar to <function>LIKE</function>, except that it
|
|
interprets the pattern using the SQL standard's definition of a
|
|
regular expression. SQL regular expressions are a curious cross
|
|
between <function>LIKE</function> notation and common regular
|
|
expression notation.
|
|
</para>
|
|
|
|
<para>
|
|
Like <function>LIKE</function>, the <function>SIMILAR TO</function>
|
|
operator succeeds only if its pattern matches the entire string;
|
|
this is unlike common regular expression behavior where the pattern
|
|
can match any part of the string.
|
|
Also like
|
|
<function>LIKE</function>, <function>SIMILAR TO</function> uses
|
|
<literal>_</> and <literal>%</> as wildcard characters denoting
|
|
any single character and any string, respectively (these are
|
|
comparable to <literal>.</> and <literal>.*</> in POSIX regular
|
|
expressions).
|
|
</para>
|
|
|
|
<para>
|
|
In addition to these facilities borrowed from <function>LIKE</function>,
|
|
<function>SIMILAR TO</function> supports these pattern-matching
|
|
metacharacters borrowed from POSIX regular expressions:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
<literal>|</literal> denotes alternation (either of two alternatives).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>*</literal> denotes repetition of the previous item zero
|
|
or more times.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>+</literal> denotes repetition of the previous item one
|
|
or more times.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>?</literal> denotes repetition of the previous item zero
|
|
or one time.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>{</><replaceable>m</><literal>}</literal> denotes repetition
|
|
of the previous item exactly <replaceable>m</> times.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>{</><replaceable>m</><literal>,}</literal> denotes repetition
|
|
of the previous item <replaceable>m</> or more times.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
<literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
|
|
denotes repetition of the previous item at least <replaceable>m</> and
|
|
not more than <replaceable>n</> times.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
Parentheses <literal>()</literal> can be used to group items into
|
|
a single logical item.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A bracket expression <literal>[...]</literal> specifies a character
|
|
class, just as in POSIX regular expressions.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
Notice that the period (<literal>.</>) is not a metacharacter
|
|
for <function>SIMILAR TO</>.
|
|
</para>
|
|
|
|
<para>
|
|
As with <function>LIKE</>, a backslash disables the special meaning
|
|
of any of these metacharacters; or a different escape character can
|
|
be specified with <literal>ESCAPE</>.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
'abc' SIMILAR TO 'abc' <lineannotation>true</lineannotation>
|
|
'abc' SIMILAR TO 'a' <lineannotation>false</lineannotation>
|
|
'abc' SIMILAR TO '%(b|d)%' <lineannotation>true</lineannotation>
|
|
'abc' SIMILAR TO '(b|c)%' <lineannotation>false</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>substring</> function with three parameters,
|
|
<function>substring(<replaceable>string</replaceable> from
|
|
<replaceable>pattern</replaceable> for
|
|
<replaceable>escape-character</replaceable>)</function>, provides
|
|
extraction of a substring that matches an SQL
|
|
regular expression pattern. As with <literal>SIMILAR TO</>, the
|
|
specified pattern must match the entire data string, or else the
|
|
function fails and returns null. To indicate the part of the
|
|
pattern that should be returned on success, the pattern must contain
|
|
two occurrences of the escape character followed by a double quote
|
|
(<literal>"</>). <!-- " font-lock sanity -->
|
|
The text matching the portion of the pattern
|
|
between these markers is returned.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples, with <literal>#"</> delimiting the return string:
|
|
<programlisting>
|
|
substring('foobar' from '%#"o_b#"%' for '#') <lineannotation>oob</lineannotation>
|
|
substring('foobar' from '#"o_b#"%' for '#') <lineannotation>NULL</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-posix-regexp">
|
|
<title><acronym>POSIX</acronym> Regular Expressions</title>
|
|
|
|
<indexterm zone="functions-posix-regexp">
|
|
<primary>regular expression</primary>
|
|
<seealso>pattern matching</seealso>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>substring</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>regexp_replace</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>regexp_matches</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>regexp_split_to_table</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>regexp_split_to_array</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<xref linkend="functions-posix-table"> lists the available
|
|
operators for pattern matching using POSIX regular expressions.
|
|
</para>
|
|
|
|
<table id="functions-posix-table">
|
|
<title>Regular Expression Match Operators</title>
|
|
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>~</literal> </entry>
|
|
<entry>Matches regular expression, case sensitive</entry>
|
|
<entry><literal>'thomas' ~ '.*thomas.*'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>~*</literal> </entry>
|
|
<entry>Matches regular expression, case insensitive</entry>
|
|
<entry><literal>'thomas' ~* '.*Thomas.*'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>!~</literal> </entry>
|
|
<entry>Does not match regular expression, case sensitive</entry>
|
|
<entry><literal>'thomas' !~ '.*Thomas.*'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>!~*</literal> </entry>
|
|
<entry>Does not match regular expression, case insensitive</entry>
|
|
<entry><literal>'thomas' !~* '.*vadim.*'</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<acronym>POSIX</acronym> regular expressions provide a more
|
|
powerful means for pattern matching than the <function>LIKE</function> and
|
|
<function>SIMILAR TO</> operators.
|
|
Many Unix tools such as <command>egrep</command>,
|
|
<command>sed</command>, or <command>awk</command> use a pattern
|
|
matching language that is similar to the one described here.
|
|
</para>
|
|
|
|
<para>
|
|
A regular expression is a character sequence that is an
|
|
abbreviated definition of a set of strings (a <firstterm>regular
|
|
set</firstterm>). A string is said to match a regular expression
|
|
if it is a member of the regular set described by the regular
|
|
expression. As with <function>LIKE</function>, pattern characters
|
|
match string characters exactly unless they are special characters
|
|
in the regular expression language — but regular expressions use
|
|
different special characters than <function>LIKE</function> does.
|
|
Unlike <function>LIKE</function> patterns, a
|
|
regular expression is allowed to match anywhere within a string, unless
|
|
the regular expression is explicitly anchored to the beginning or
|
|
end of the string.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
'abc' ~ 'abc' <lineannotation>true</lineannotation>
|
|
'abc' ~ '^a' <lineannotation>true</lineannotation>
|
|
'abc' ~ '(b|d)' <lineannotation>true</lineannotation>
|
|
'abc' ~ '^(b|c)' <lineannotation>false</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The <acronym>POSIX</acronym> pattern language is described in much
|
|
greater detail below.
|
|
</para>
|
|
|
|
<para>
|
|
The <function>substring</> function with two parameters,
|
|
<function>substring(<replaceable>string</replaceable> from
|
|
<replaceable>pattern</replaceable>)</function>, provides extraction of a
|
|
substring
|
|
that matches a POSIX regular expression pattern. It returns null if
|
|
there is no match, otherwise the portion of the text that matched the
|
|
pattern. But if the pattern contains any parentheses, the portion
|
|
of the text that matched the first parenthesized subexpression (the
|
|
one whose left parenthesis comes first) is
|
|
returned. You can put parentheses around the whole expression
|
|
if you want to use parentheses within it without triggering this
|
|
exception. If you need parentheses in the pattern before the
|
|
subexpression you want to extract, see the non-capturing parentheses
|
|
described below.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
substring('foobar' from 'o.b') <lineannotation>oob</lineannotation>
|
|
substring('foobar' from 'o(.)b') <lineannotation>o</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>regexp_replace</> function provides substitution of
|
|
new text for substrings that match POSIX regular expression patterns.
|
|
It has the syntax
|
|
<function>regexp_replace</function>(<replaceable>source</>,
|
|
<replaceable>pattern</>, <replaceable>replacement</>
|
|
<optional>, <replaceable>flags</> </optional>).
|
|
The <replaceable>source</> string is returned unchanged if
|
|
there is no match to the <replaceable>pattern</>. If there is a
|
|
match, the <replaceable>source</> string is returned with the
|
|
<replaceable>replacement</> string substituted for the matching
|
|
substring. The <replaceable>replacement</> string can contain
|
|
<literal>\</><replaceable>n</>, where <replaceable>n</> is 1
|
|
through 9, to indicate that the source substring matching the
|
|
<replaceable>n</>'th parenthesized subexpression of the pattern should be
|
|
inserted, and it can contain <literal>\&</> to indicate that the
|
|
substring matching the entire pattern should be inserted. Write
|
|
<literal>\\</> if you need to put a literal backslash in the replacement
|
|
text. (As always, remember to double backslashes written in literal
|
|
constant strings, assuming escape string syntax is used.)
|
|
The <replaceable>flags</> parameter is an optional text
|
|
string containing zero or more single-letter flags that change the
|
|
function's behavior. Flag <literal>i</> specifies case-insensitive
|
|
matching, while flag <literal>g</> specifies replacement of each matching
|
|
substring rather than only the first one. Other supported flags are
|
|
described in <xref linkend="posix-embedded-options-table">.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
regexp_replace('foobarbaz', 'b..', 'X')
|
|
<lineannotation>fooXbaz</lineannotation>
|
|
regexp_replace('foobarbaz', 'b..', 'X', 'g')
|
|
<lineannotation>fooXX</lineannotation>
|
|
regexp_replace('foobarbaz', 'b(..)', E'X\\1Y', 'g')
|
|
<lineannotation>fooXarYXazY</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>regexp_matches</> function returns a text array of
|
|
all of the captured substrings resulting from matching a POSIX
|
|
regular expression pattern. It has the syntax
|
|
<function>regexp_matches</function>(<replaceable>string</>, <replaceable>pattern</>
|
|
<optional>, <replaceable>flags</> </optional>).
|
|
The function can return no rows, one row, or multiple rows (see
|
|
the <literal>g</> flag below). If the <replaceable>pattern</>
|
|
does not match, the function returns no rows. If the pattern
|
|
contains no parenthesized subexpressions, then each row
|
|
returned is a single-element text array containing the substring
|
|
matching the whole pattern. If the pattern contains parenthesized
|
|
subexpressions, the function returns a text array whose
|
|
<replaceable>n</>'th element is the substring matching the
|
|
<replaceable>n</>'th parenthesized subexpression of the pattern
|
|
(not counting <quote>non-capturing</> parentheses; see below for
|
|
details).
|
|
The <replaceable>flags</> parameter is an optional text
|
|
string containing zero or more single-letter flags that change the
|
|
function's behavior. Flag <literal>g</> causes the function to find
|
|
each match in the string, not only the first one, and return a row for
|
|
each such match. Other supported
|
|
flags are described in <xref linkend="posix-embedded-options-table">.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
SELECT regexp_matches('foobarbequebaz', '(bar)(beque)');
|
|
regexp_matches
|
|
----------------
|
|
{bar,beque}
|
|
(1 row)
|
|
|
|
SELECT regexp_matches('foobarbequebazilbarfbonk', '(b[^b]+)(b[^b]+)', 'g');
|
|
regexp_matches
|
|
----------------
|
|
{bar,beque}
|
|
{bazil,barf}
|
|
(2 rows)
|
|
|
|
SELECT regexp_matches('foobarbequebaz', 'barbeque');
|
|
regexp_matches
|
|
----------------
|
|
{barbeque}
|
|
(1 row)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
It is possible to force <function>regexp_matches()</> to always
|
|
return one row by using a sub-select; this is particularly useful
|
|
in a <literal>SELECT</> target list when you want all rows
|
|
returned, even non-matching ones:
|
|
<programlisting>
|
|
SELECT col1, (SELECT regexp_matches(col2, '(bar)(beque)')) FROM tab;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>regexp_split_to_table</> function splits a string using a POSIX
|
|
regular expression pattern as a delimiter. It has the syntax
|
|
<function>regexp_split_to_table</function>(<replaceable>string</>, <replaceable>pattern</>
|
|
<optional>, <replaceable>flags</> </optional>).
|
|
If there is no match to the <replaceable>pattern</>, the function returns the
|
|
<replaceable>string</>. If there is at least one match, for each match it returns
|
|
the text from the end of the last match (or the beginning of the string)
|
|
to the beginning of the match. When there are no more matches, it
|
|
returns the text from the end of the last match to the end of the string.
|
|
The <replaceable>flags</> parameter is an optional text string containing
|
|
zero or more single-letter flags that change the function's behavior.
|
|
<function>regexp_split_to_table</function> supports the flags described in
|
|
<xref linkend="posix-embedded-options-table">.
|
|
</para>
|
|
|
|
<para>
|
|
The <function>regexp_split_to_array</> function behaves the same as
|
|
<function>regexp_split_to_table</>, except that <function>regexp_split_to_array</>
|
|
returns its result as an array of <type>text</>. It has the syntax
|
|
<function>regexp_split_to_array</function>(<replaceable>string</>, <replaceable>pattern</>
|
|
<optional>, <replaceable>flags</> </optional>).
|
|
The parameters are the same as for <function>regexp_split_to_table</>.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<programlisting>
|
|
|
|
SELECT foo FROM regexp_split_to_table('the quick brown fox jumped over the lazy dog', E'\\s+') AS foo;
|
|
foo
|
|
--------
|
|
the
|
|
quick
|
|
brown
|
|
fox
|
|
jumped
|
|
over
|
|
the
|
|
lazy
|
|
dog
|
|
(9 rows)
|
|
|
|
SELECT regexp_split_to_array('the quick brown fox jumped over the lazy dog', E'\\s+');
|
|
regexp_split_to_array
|
|
------------------------------------------------
|
|
{the,quick,brown,fox,jumped,over,the,lazy,dog}
|
|
(1 row)
|
|
|
|
SELECT foo FROM regexp_split_to_table('the quick brown fox', E'\\s*') AS foo;
|
|
foo
|
|
-----
|
|
t
|
|
h
|
|
e
|
|
q
|
|
u
|
|
i
|
|
c
|
|
k
|
|
b
|
|
r
|
|
o
|
|
w
|
|
n
|
|
f
|
|
o
|
|
x
|
|
(16 rows)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
As the last example demonstrates, the regexp split functions ignore
|
|
zero-length matches that occur at the start or end of the string
|
|
or immediately after a previous match. This is contrary to the strict
|
|
definition of regexp matching that is implemented by
|
|
<function>regexp_matches</>, but is usually the most convenient behavior
|
|
in practice. Other software systems such as Perl use similar definitions.
|
|
</para>
|
|
|
|
<!-- derived from the re_syntax.n man page -->
|
|
|
|
<sect3 id="posix-syntax-details">
|
|
<title>Regular Expression Details</title>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname>'s regular expressions are implemented
|
|
using a software package written by Henry Spencer. Much of
|
|
the description of regular expressions below is copied verbatim from his
|
|
manual.
|
|
</para>
|
|
|
|
<para>
|
|
Regular expressions (<acronym>RE</acronym>s), as defined in
|
|
<acronym>POSIX</acronym> 1003.2, come in two forms:
|
|
<firstterm>extended</> <acronym>RE</acronym>s or <acronym>ERE</>s
|
|
(roughly those of <command>egrep</command>), and
|
|
<firstterm>basic</> <acronym>RE</acronym>s or <acronym>BRE</>s
|
|
(roughly those of <command>ed</command>).
|
|
<productname>PostgreSQL</productname> supports both forms, and
|
|
also implements some extensions
|
|
that are not in the POSIX standard, but have become widely used
|
|
due to their availability in programming languages such as Perl and Tcl.
|
|
<acronym>RE</acronym>s using these non-POSIX extensions are called
|
|
<firstterm>advanced</> <acronym>RE</acronym>s or <acronym>ARE</>s
|
|
in this documentation. AREs are almost an exact superset of EREs,
|
|
but BREs have several notational incompatibilities (as well as being
|
|
much more limited).
|
|
We first describe the ARE and ERE forms, noting features that apply
|
|
only to AREs, and then describe how BREs differ.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
<productname>PostgreSQL</> always initially presumes that a regular
|
|
expression follows the ARE rules. However, the more limited ERE or
|
|
BRE rules can be chosen by prepending an <firstterm>embedded option</>
|
|
to the RE pattern, as described in <xref linkend="posix-metasyntax">.
|
|
This can be useful for compatibility with applications that expect
|
|
exactly the <acronym>POSIX</acronym> 1003.2 rules.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
A regular expression is defined as one or more
|
|
<firstterm>branches</firstterm>, separated by
|
|
<literal>|</literal>. It matches anything that matches one of the
|
|
branches.
|
|
</para>
|
|
|
|
<para>
|
|
A branch is zero or more <firstterm>quantified atoms</> or
|
|
<firstterm>constraints</>, concatenated.
|
|
It matches a match for the first, followed by a match for the second, etc;
|
|
an empty branch matches the empty string.
|
|
</para>
|
|
|
|
<para>
|
|
A quantified atom is an <firstterm>atom</> possibly followed
|
|
by a single <firstterm>quantifier</>.
|
|
Without a quantifier, it matches a match for the atom.
|
|
With a quantifier, it can match some number of matches of the atom.
|
|
An <firstterm>atom</firstterm> can be any of the possibilities
|
|
shown in <xref linkend="posix-atoms-table">.
|
|
The possible quantifiers and their meanings are shown in
|
|
<xref linkend="posix-quantifiers-table">.
|
|
</para>
|
|
|
|
<para>
|
|
A <firstterm>constraint</> matches an empty string, but matches only when
|
|
specific conditions are met. A constraint can be used where an atom
|
|
could be used, except it cannot be followed by a quantifier.
|
|
The simple constraints are shown in
|
|
<xref linkend="posix-constraints-table">;
|
|
some more constraints are described later.
|
|
</para>
|
|
|
|
|
|
<table id="posix-atoms-table">
|
|
<title>Regular Expression Atoms</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Atom</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>(</><replaceable>re</><literal>)</> </entry>
|
|
<entry> (where <replaceable>re</> is any regular expression)
|
|
matches a match for
|
|
<replaceable>re</>, with the match noted for possible reporting </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?:</><replaceable>re</><literal>)</> </entry>
|
|
<entry> as above, but the match is not noted for reporting
|
|
(a <quote>non-capturing</> set of parentheses)
|
|
(AREs only) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>.</> </entry>
|
|
<entry> matches any single character </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>[</><replaceable>chars</><literal>]</> </entry>
|
|
<entry> a <firstterm>bracket expression</>,
|
|
matching any one of the <replaceable>chars</> (see
|
|
<xref linkend="posix-bracket-expressions"> for more detail) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</><replaceable>k</> </entry>
|
|
<entry> (where <replaceable>k</> is a non-alphanumeric character)
|
|
matches that character taken as an ordinary character,
|
|
e.g., <literal>\\</> matches a backslash character </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</><replaceable>c</> </entry>
|
|
<entry> where <replaceable>c</> is alphanumeric
|
|
(possibly followed by other characters)
|
|
is an <firstterm>escape</>, see <xref linkend="posix-escape-sequences">
|
|
(AREs only; in EREs and BREs, this matches <replaceable>c</>) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</> </entry>
|
|
<entry> when followed by a character other than a digit,
|
|
matches the left-brace character <literal>{</>;
|
|
when followed by a digit, it is the beginning of a
|
|
<replaceable>bound</> (see below) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <replaceable>x</> </entry>
|
|
<entry> where <replaceable>x</> is a single character with no other
|
|
significance, matches that character </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
An RE cannot end with <literal>\</>.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Remember that the backslash (<literal>\</literal>) already has a special
|
|
meaning in <productname>PostgreSQL</> string literals.
|
|
To write a pattern constant that contains a backslash,
|
|
you must write two backslashes in the statement, assuming escape
|
|
string syntax is used (see <xref linkend="sql-syntax-strings">).
|
|
</para>
|
|
</note>
|
|
|
|
<table id="posix-quantifiers-table">
|
|
<title>Regular Expression Quantifiers</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Quantifier</entry>
|
|
<entry>Matches</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>*</> </entry>
|
|
<entry> a sequence of 0 or more matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</> </entry>
|
|
<entry> a sequence of 1 or more matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>?</> </entry>
|
|
<entry> a sequence of 0 or 1 matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</><replaceable>m</><literal>}</> </entry>
|
|
<entry> a sequence of exactly <replaceable>m</> matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</><replaceable>m</><literal>,}</> </entry>
|
|
<entry> a sequence of <replaceable>m</> or more matches of the atom </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
|
|
<entry> a sequence of <replaceable>m</> through <replaceable>n</>
|
|
(inclusive) matches of the atom; <replaceable>m</> cannot exceed
|
|
<replaceable>n</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>*?</> </entry>
|
|
<entry> non-greedy version of <literal>*</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+?</> </entry>
|
|
<entry> non-greedy version of <literal>+</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>??</> </entry>
|
|
<entry> non-greedy version of <literal>?</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</><replaceable>m</><literal>}?</> </entry>
|
|
<entry> non-greedy version of <literal>{</><replaceable>m</><literal>}</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>{</><replaceable>m</><literal>,}?</> </entry>
|
|
<entry> non-greedy version of <literal>{</><replaceable>m</><literal>,}</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</> </entry>
|
|
<entry> non-greedy version of <literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</> </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The forms using <literal>{</><replaceable>...</><literal>}</>
|
|
are known as <firstterm>bounds</>.
|
|
The numbers <replaceable>m</> and <replaceable>n</> within a bound are
|
|
unsigned decimal integers with permissible values from 0 to 255 inclusive.
|
|
</para>
|
|
|
|
<para>
|
|
<firstterm>Non-greedy</> quantifiers (available in AREs only) match the
|
|
same possibilities as their corresponding normal (<firstterm>greedy</>)
|
|
counterparts, but prefer the smallest number rather than the largest
|
|
number of matches.
|
|
See <xref linkend="posix-matching-rules"> for more detail.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
A quantifier cannot immediately follow another quantifier, e.g.,
|
|
<literal>**</> is invalid.
|
|
A quantifier cannot
|
|
begin an expression or subexpression or follow
|
|
<literal>^</literal> or <literal>|</literal>.
|
|
</para>
|
|
</note>
|
|
|
|
<table id="posix-constraints-table">
|
|
<title>Regular Expression Constraints</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Constraint</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>^</> </entry>
|
|
<entry> matches at the beginning of the string </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>$</> </entry>
|
|
<entry> matches at the end of the string </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?=</><replaceable>re</><literal>)</> </entry>
|
|
<entry> <firstterm>positive lookahead</> matches at any point
|
|
where a substring matching <replaceable>re</> begins
|
|
(AREs only) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>(?!</><replaceable>re</><literal>)</> </entry>
|
|
<entry> <firstterm>negative lookahead</> matches at any point
|
|
where no substring matching <replaceable>re</> begins
|
|
(AREs only) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Lookahead constraints cannot contain <firstterm>back references</>
|
|
(see <xref linkend="posix-escape-sequences">),
|
|
and all parentheses within them are considered non-capturing.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="posix-bracket-expressions">
|
|
<title>Bracket Expressions</title>
|
|
|
|
<para>
|
|
A <firstterm>bracket expression</firstterm> is a list of
|
|
characters enclosed in <literal>[]</literal>. It normally matches
|
|
any single character from the list (but see below). If the list
|
|
begins with <literal>^</literal>, it matches any single character
|
|
<emphasis>not</> from the rest of the list.
|
|
If two characters
|
|
in the list are separated by <literal>-</literal>, this is
|
|
shorthand for the full range of characters between those two
|
|
(inclusive) in the collating sequence,
|
|
e.g., <literal>[0-9]</literal> in <acronym>ASCII</acronym> matches
|
|
any decimal digit. It is illegal for two ranges to share an
|
|
endpoint, e.g., <literal>a-c-e</literal>. Ranges are very
|
|
collating-sequence-dependent, so portable programs should avoid
|
|
relying on them.
|
|
</para>
|
|
|
|
<para>
|
|
To include a literal <literal>]</literal> in the list, make it the
|
|
first character (after <literal>^</literal>, if that is used). To
|
|
include a literal <literal>-</literal>, make it the first or last
|
|
character, or the second endpoint of a range. To use a literal
|
|
<literal>-</literal> as the first endpoint of a range, enclose it
|
|
in <literal>[.</literal> and <literal>.]</literal> to make it a
|
|
collating element (see below). With the exception of these characters,
|
|
some combinations using <literal>[</literal>
|
|
(see next paragraphs), and escapes (AREs only), all other special
|
|
characters lose their special significance within a bracket expression.
|
|
In particular, <literal>\</literal> is not special when following
|
|
ERE or BRE rules, though it is special (as introducing an escape)
|
|
in AREs.
|
|
</para>
|
|
|
|
<para>
|
|
Within a bracket expression, a collating element (a character, a
|
|
multiple-character sequence that collates as if it were a single
|
|
character, or a collating-sequence name for either) enclosed in
|
|
<literal>[.</literal> and <literal>.]</literal> stands for the
|
|
sequence of characters of that collating element. The sequence is
|
|
treated as a single element of the bracket expression's list. This
|
|
allows a bracket
|
|
expression containing a multiple-character collating element to
|
|
match more than one character, e.g., if the collating sequence
|
|
includes a <literal>ch</literal> collating element, then the RE
|
|
<literal>[[.ch.]]*c</literal> matches the first five characters of
|
|
<literal>chchcc</literal>.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
<productname>PostgreSQL</> currently does not support multi-character collating
|
|
elements. This information describes possible future behavior.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
Within a bracket expression, a collating element enclosed in
|
|
<literal>[=</literal> and <literal>=]</literal> is an <firstterm>equivalence
|
|
class</>, standing for the sequences of characters of all collating
|
|
elements equivalent to that one, including itself. (If there are
|
|
no other equivalent collating elements, the treatment is as if the
|
|
enclosing delimiters were <literal>[.</literal> and
|
|
<literal>.]</literal>.) For example, if <literal>o</literal> and
|
|
<literal>^</literal> are the members of an equivalence class, then
|
|
<literal>[[=o=]]</literal>, <literal>[[=^=]]</literal>, and
|
|
<literal>[o^]</literal> are all synonymous. An equivalence class
|
|
cannot be an endpoint of a range.
|
|
</para>
|
|
|
|
<para>
|
|
Within a bracket expression, the name of a character class
|
|
enclosed in <literal>[:</literal> and <literal>:]</literal> stands
|
|
for the list of all characters belonging to that class. Standard
|
|
character class names are: <literal>alnum</literal>,
|
|
<literal>alpha</literal>, <literal>blank</literal>,
|
|
<literal>cntrl</literal>, <literal>digit</literal>,
|
|
<literal>graph</literal>, <literal>lower</literal>,
|
|
<literal>print</literal>, <literal>punct</literal>,
|
|
<literal>space</literal>, <literal>upper</literal>,
|
|
<literal>xdigit</literal>. These stand for the character classes
|
|
defined in
|
|
<citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>.
|
|
A locale can provide others. A character class cannot be used as
|
|
an endpoint of a range.
|
|
</para>
|
|
|
|
<para>
|
|
There are two special cases of bracket expressions: the bracket
|
|
expressions <literal>[[:<:]]</literal> and
|
|
<literal>[[:>:]]</literal> are constraints,
|
|
matching empty strings at the beginning
|
|
and end of a word respectively. A word is defined as a sequence
|
|
of word characters that is neither preceded nor followed by word
|
|
characters. A word character is an <literal>alnum</> character (as
|
|
defined by
|
|
<citerefentry><refentrytitle>ctype</refentrytitle><manvolnum>3</manvolnum></citerefentry>)
|
|
or an underscore. This is an extension, compatible with but not
|
|
specified by <acronym>POSIX</acronym> 1003.2, and should be used with
|
|
caution in software intended to be portable to other systems.
|
|
The constraint escapes described below are usually preferable; they
|
|
are no more standard, but are easier to type.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="posix-escape-sequences">
|
|
<title>Regular Expression Escapes</title>
|
|
|
|
<para>
|
|
<firstterm>Escapes</> are special sequences beginning with <literal>\</>
|
|
followed by an alphanumeric character. Escapes come in several varieties:
|
|
character entry, class shorthands, constraint escapes, and back references.
|
|
A <literal>\</> followed by an alphanumeric character but not constituting
|
|
a valid escape is illegal in AREs.
|
|
In EREs, there are no escapes: outside a bracket expression,
|
|
a <literal>\</> followed by an alphanumeric character merely stands for
|
|
that character as an ordinary character, and inside a bracket expression,
|
|
<literal>\</> is an ordinary character.
|
|
(The latter is the one actual incompatibility between EREs and AREs.)
|
|
</para>
|
|
|
|
<para>
|
|
<firstterm>Character-entry escapes</> exist to make it easier to specify
|
|
non-printing and other inconvenient characters in REs. They are
|
|
shown in <xref linkend="posix-character-entry-escapes-table">.
|
|
</para>
|
|
|
|
<para>
|
|
<firstterm>Class-shorthand escapes</> provide shorthands for certain
|
|
commonly-used character classes. They are
|
|
shown in <xref linkend="posix-class-shorthand-escapes-table">.
|
|
</para>
|
|
|
|
<para>
|
|
A <firstterm>constraint escape</> is a constraint,
|
|
matching the empty string if specific conditions are met,
|
|
written as an escape. They are
|
|
shown in <xref linkend="posix-constraint-escapes-table">.
|
|
</para>
|
|
|
|
<para>
|
|
A <firstterm>back reference</> (<literal>\</><replaceable>n</>) matches the
|
|
same string matched by the previous parenthesized subexpression specified
|
|
by the number <replaceable>n</>
|
|
(see <xref linkend="posix-constraint-backref-table">). For example,
|
|
<literal>([bc])\1</> matches <literal>bb</> or <literal>cc</>
|
|
but not <literal>bc</> or <literal>cb</>.
|
|
The subexpression must entirely precede the back reference in the RE.
|
|
Subexpressions are numbered in the order of their leading parentheses.
|
|
Non-capturing parentheses do not define subexpressions.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Keep in mind that an escape's leading <literal>\</> will need to be
|
|
doubled when entering the pattern as an SQL string constant. For example:
|
|
<programlisting>
|
|
'123' ~ E'^\\d{3}' <lineannotation>true</lineannotation>
|
|
</programlisting>
|
|
</para>
|
|
</note>
|
|
|
|
<table id="posix-character-entry-escapes-table">
|
|
<title>Regular Expression Character-entry Escapes</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Escape</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>\a</> </entry>
|
|
<entry> alert (bell) character, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\b</> </entry>
|
|
<entry> backspace, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\B</> </entry>
|
|
<entry> synonym for backslash (<literal>\</>) to help reduce the need for backslash
|
|
doubling </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\c</><replaceable>X</> </entry>
|
|
<entry> (where <replaceable>X</> is any character) the character whose
|
|
low-order 5 bits are the same as those of
|
|
<replaceable>X</>, and whose other bits are all zero </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\e</> </entry>
|
|
<entry> the character whose collating-sequence name
|
|
is <literal>ESC</>,
|
|
or failing that, the character with octal value 033 </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\f</> </entry>
|
|
<entry> form feed, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\n</> </entry>
|
|
<entry> newline, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\r</> </entry>
|
|
<entry> carriage return, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\t</> </entry>
|
|
<entry> horizontal tab, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\u</><replaceable>wxyz</> </entry>
|
|
<entry> (where <replaceable>wxyz</> is exactly four hexadecimal digits)
|
|
the UTF16 (Unicode, 16-bit) character <literal>U+</><replaceable>wxyz</>
|
|
in the local byte ordering </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\U</><replaceable>stuvwxyz</> </entry>
|
|
<entry> (where <replaceable>stuvwxyz</> is exactly eight hexadecimal
|
|
digits)
|
|
reserved for a hypothetical Unicode extension to 32 bits
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\v</> </entry>
|
|
<entry> vertical tab, as in C </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\x</><replaceable>hhh</> </entry>
|
|
<entry> (where <replaceable>hhh</> is any sequence of hexadecimal
|
|
digits)
|
|
the character whose hexadecimal value is
|
|
<literal>0x</><replaceable>hhh</>
|
|
(a single character no matter how many hexadecimal digits are used)
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\0</> </entry>
|
|
<entry> the character whose value is <literal>0</> (the null byte)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</><replaceable>xy</> </entry>
|
|
<entry> (where <replaceable>xy</> is exactly two octal digits,
|
|
and is not a <firstterm>back reference</>)
|
|
the character whose octal value is
|
|
<literal>0</><replaceable>xy</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</><replaceable>xyz</> </entry>
|
|
<entry> (where <replaceable>xyz</> is exactly three octal digits,
|
|
and is not a <firstterm>back reference</>)
|
|
the character whose octal value is
|
|
<literal>0</><replaceable>xyz</> </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Hexadecimal digits are <literal>0</>-<literal>9</>,
|
|
<literal>a</>-<literal>f</>, and <literal>A</>-<literal>F</>.
|
|
Octal digits are <literal>0</>-<literal>7</>.
|
|
</para>
|
|
|
|
<para>
|
|
The character-entry escapes are always taken as ordinary characters.
|
|
For example, <literal>\135</> is <literal>]</> in ASCII, but
|
|
<literal>\135</> does not terminate a bracket expression.
|
|
</para>
|
|
|
|
<table id="posix-class-shorthand-escapes-table">
|
|
<title>Regular Expression Class-shorthand Escapes</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Escape</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>\d</> </entry>
|
|
<entry> <literal>[[:digit:]]</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\s</> </entry>
|
|
<entry> <literal>[[:space:]]</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\w</> </entry>
|
|
<entry> <literal>[[:alnum:]_]</>
|
|
(note underscore is included) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\D</> </entry>
|
|
<entry> <literal>[^[:digit:]]</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\S</> </entry>
|
|
<entry> <literal>[^[:space:]]</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\W</> </entry>
|
|
<entry> <literal>[^[:alnum:]_]</>
|
|
(note underscore is included) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Within bracket expressions, <literal>\d</>, <literal>\s</>,
|
|
and <literal>\w</> lose their outer brackets,
|
|
and <literal>\D</>, <literal>\S</>, and <literal>\W</> are illegal.
|
|
(So, for example, <literal>[a-c\d]</> is equivalent to
|
|
<literal>[a-c[:digit:]]</>.
|
|
Also, <literal>[a-c\D]</>, which is equivalent to
|
|
<literal>[a-c^[:digit:]]</>, is illegal.)
|
|
</para>
|
|
|
|
<table id="posix-constraint-escapes-table">
|
|
<title>Regular Expression Constraint Escapes</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Escape</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>\A</> </entry>
|
|
<entry> matches only at the beginning of the string
|
|
(see <xref linkend="posix-matching-rules"> for how this differs from
|
|
<literal>^</>) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\m</> </entry>
|
|
<entry> matches only at the beginning of a word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\M</> </entry>
|
|
<entry> matches only at the end of a word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\y</> </entry>
|
|
<entry> matches only at the beginning or end of a word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\Y</> </entry>
|
|
<entry> matches only at a point that is not the beginning or end of a
|
|
word </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\Z</> </entry>
|
|
<entry> matches only at the end of the string
|
|
(see <xref linkend="posix-matching-rules"> for how this differs from
|
|
<literal>$</>) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
A word is defined as in the specification of
|
|
<literal>[[:<:]]</> and <literal>[[:>:]]</> above.
|
|
Constraint escapes are illegal within bracket expressions.
|
|
</para>
|
|
|
|
<table id="posix-constraint-backref-table">
|
|
<title>Regular Expression Back References</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Escape</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>\</><replaceable>m</> </entry>
|
|
<entry> (where <replaceable>m</> is a nonzero digit)
|
|
a back reference to the <replaceable>m</>'th subexpression </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>\</><replaceable>mnn</> </entry>
|
|
<entry> (where <replaceable>m</> is a nonzero digit, and
|
|
<replaceable>nn</> is some more digits, and the decimal value
|
|
<replaceable>mnn</> is not greater than the number of closing capturing
|
|
parentheses seen so far)
|
|
a back reference to the <replaceable>mnn</>'th subexpression </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
There is an inherent ambiguity between octal character-entry
|
|
escapes and back references, which is resolved by the following heuristics,
|
|
as hinted at above.
|
|
A leading zero always indicates an octal escape.
|
|
A single non-zero digit, not followed by another digit,
|
|
is always taken as a back reference.
|
|
A multi-digit sequence not starting with a zero is taken as a back
|
|
reference if it comes after a suitable subexpression
|
|
(i.e., the number is in the legal range for a back reference),
|
|
and otherwise is taken as octal.
|
|
</para>
|
|
</note>
|
|
</sect3>
|
|
|
|
<sect3 id="posix-metasyntax">
|
|
<title>Regular Expression Metasyntax</title>
|
|
|
|
<para>
|
|
In addition to the main syntax described above, there are some special
|
|
forms and miscellaneous syntactic facilities available.
|
|
</para>
|
|
|
|
<para>
|
|
An RE can begin with one of two special <firstterm>director</> prefixes.
|
|
If an RE begins with <literal>***:</>,
|
|
the rest of the RE is taken as an ARE. (This normally has no effect in
|
|
<productname>PostgreSQL</>, since REs are assumed to be AREs;
|
|
but it does have an effect if ERE or BRE mode had been specified by
|
|
the <replaceable>flags</> parameter to a regex function.)
|
|
If an RE begins with <literal>***=</>,
|
|
the rest of the RE is taken to be a literal string,
|
|
with all characters considered ordinary characters.
|
|
</para>
|
|
|
|
<para>
|
|
An ARE can begin with <firstterm>embedded options</>:
|
|
a sequence <literal>(?</><replaceable>xyz</><literal>)</>
|
|
(where <replaceable>xyz</> is one or more alphabetic characters)
|
|
specifies options affecting the rest of the RE.
|
|
These options override any previously determined options —
|
|
in particular, they can override the case-sensitivity behavior implied by
|
|
a regex operator, or the <replaceable>flags</> parameter to a regex
|
|
function.
|
|
The available option letters are
|
|
shown in <xref linkend="posix-embedded-options-table">.
|
|
Note that these same option letters are used in the <replaceable>flags</>
|
|
parameters of regex functions.
|
|
</para>
|
|
|
|
<table id="posix-embedded-options-table">
|
|
<title>ARE Embedded-option Letters</title>
|
|
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Option</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>b</> </entry>
|
|
<entry> rest of RE is a BRE </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>c</> </entry>
|
|
<entry> case-sensitive matching (overrides operator type) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>e</> </entry>
|
|
<entry> rest of RE is an ERE </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>i</> </entry>
|
|
<entry> case-insensitive matching (see
|
|
<xref linkend="posix-matching-rules">) (overrides operator type) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>m</> </entry>
|
|
<entry> historical synonym for <literal>n</> </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>n</> </entry>
|
|
<entry> newline-sensitive matching (see
|
|
<xref linkend="posix-matching-rules">) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>p</> </entry>
|
|
<entry> partial newline-sensitive matching (see
|
|
<xref linkend="posix-matching-rules">) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>q</> </entry>
|
|
<entry> rest of RE is a literal (<quote>quoted</>) string, all ordinary
|
|
characters </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>s</> </entry>
|
|
<entry> non-newline-sensitive matching (default) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>t</> </entry>
|
|
<entry> tight syntax (default; see below) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>w</> </entry>
|
|
<entry> inverse partial newline-sensitive (<quote>weird</>) matching
|
|
(see <xref linkend="posix-matching-rules">) </entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>x</> </entry>
|
|
<entry> expanded syntax (see below) </entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Embedded options take effect at the <literal>)</> terminating the sequence.
|
|
They can appear only at the start of an ARE (after the
|
|
<literal>***:</> director if any).
|
|
</para>
|
|
|
|
<para>
|
|
In addition to the usual (<firstterm>tight</>) RE syntax, in which all
|
|
characters are significant, there is an <firstterm>expanded</> syntax,
|
|
available by specifying the embedded <literal>x</> option.
|
|
In the expanded syntax,
|
|
white-space characters in the RE are ignored, as are
|
|
all characters between a <literal>#</>
|
|
and the following newline (or the end of the RE). This
|
|
permits paragraphing and commenting a complex RE.
|
|
There are three exceptions to that basic rule:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
a white-space character or <literal>#</> preceded by <literal>\</> is
|
|
retained
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
white space or <literal>#</> within a bracket expression is retained
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
white space and comments cannot appear within multi-character symbols,
|
|
such as <literal>(?:</>
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
|
|
For this purpose, white-space characters are blank, tab, newline, and
|
|
any character that belongs to the <replaceable>space</> character class.
|
|
</para>
|
|
|
|
<para>
|
|
Finally, in an ARE, outside bracket expressions, the sequence
|
|
<literal>(?#</><replaceable>ttt</><literal>)</>
|
|
(where <replaceable>ttt</> is any text not containing a <literal>)</>)
|
|
is a comment, completely ignored.
|
|
Again, this is not allowed between the characters of
|
|
multi-character symbols, like <literal>(?:</>.
|
|
Such comments are more a historical artifact than a useful facility,
|
|
and their use is deprecated; use the expanded syntax instead.
|
|
</para>
|
|
|
|
<para>
|
|
<emphasis>None</> of these metasyntax extensions is available if
|
|
an initial <literal>***=</> director
|
|
has specified that the user's input be treated as a literal string
|
|
rather than as an RE.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="posix-matching-rules">
|
|
<title>Regular Expression Matching Rules</title>
|
|
|
|
<para>
|
|
In the event that an RE could match more than one substring of a given
|
|
string, the RE matches the one starting earliest in the string.
|
|
If the RE could match more than one substring starting at that point,
|
|
either the longest possible match or the shortest possible match will
|
|
be taken, depending on whether the RE is <firstterm>greedy</> or
|
|
<firstterm>non-greedy</>.
|
|
</para>
|
|
|
|
<para>
|
|
Whether an RE is greedy or not is determined by the following rules:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
Most atoms, and all constraints, have no greediness attribute (because
|
|
they cannot match variable amounts of text anyway).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
Adding parentheses around an RE does not change its greediness.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A quantified atom with a fixed-repetition quantifier
|
|
(<literal>{</><replaceable>m</><literal>}</>
|
|
or
|
|
<literal>{</><replaceable>m</><literal>}?</>)
|
|
has the same greediness (possibly none) as the atom itself.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A quantified atom with other normal quantifiers (including
|
|
<literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}</>
|
|
with <replaceable>m</> equal to <replaceable>n</>)
|
|
is greedy (prefers longest match).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A quantified atom with a non-greedy quantifier (including
|
|
<literal>{</><replaceable>m</><literal>,</><replaceable>n</><literal>}?</>
|
|
with <replaceable>m</> equal to <replaceable>n</>)
|
|
is non-greedy (prefers shortest match).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
A branch — that is, an RE that has no top-level
|
|
<literal>|</> operator — has the same greediness as the first
|
|
quantified atom in it that has a greediness attribute.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
An RE consisting of two or more branches connected by the
|
|
<literal>|</> operator is always greedy.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
The above rules associate greediness attributes not only with individual
|
|
quantified atoms, but with branches and entire REs that contain quantified
|
|
atoms. What that means is that the matching is done in such a way that
|
|
the branch, or whole RE, matches the longest or shortest possible
|
|
substring <emphasis>as a whole</>. Once the length of the entire match
|
|
is determined, the part of it that matches any particular subexpression
|
|
is determined on the basis of the greediness attribute of that
|
|
subexpression, with subexpressions starting earlier in the RE taking
|
|
priority over ones starting later.
|
|
</para>
|
|
|
|
<para>
|
|
An example of what this means:
|
|
<screen>
|
|
SELECT SUBSTRING('XY1234Z', 'Y*([0-9]{1,3})');
|
|
<lineannotation>Result: </lineannotation><computeroutput>123</computeroutput>
|
|
SELECT SUBSTRING('XY1234Z', 'Y*?([0-9]{1,3})');
|
|
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
|
|
</screen>
|
|
In the first case, the RE as a whole is greedy because <literal>Y*</>
|
|
is greedy. It can match beginning at the <literal>Y</>, and it matches
|
|
the longest possible string starting there, i.e., <literal>Y123</>.
|
|
The output is the parenthesized part of that, or <literal>123</>.
|
|
In the second case, the RE as a whole is non-greedy because <literal>Y*?</>
|
|
is non-greedy. It can match beginning at the <literal>Y</>, and it matches
|
|
the shortest possible string starting there, i.e., <literal>Y1</>.
|
|
The subexpression <literal>[0-9]{1,3}</> is greedy but it cannot change
|
|
the decision as to the overall match length; so it is forced to match
|
|
just <literal>1</>.
|
|
</para>
|
|
|
|
<para>
|
|
In short, when an RE contains both greedy and non-greedy subexpressions,
|
|
the total match length is either as long as possible or as short as
|
|
possible, according to the attribute assigned to the whole RE. The
|
|
attributes assigned to the subexpressions only affect how much of that
|
|
match they are allowed to <quote>eat</> relative to each other.
|
|
</para>
|
|
|
|
<para>
|
|
The quantifiers <literal>{1,1}</> and <literal>{1,1}?</>
|
|
can be used to force greediness or non-greediness, respectively,
|
|
on a subexpression or a whole RE.
|
|
</para>
|
|
|
|
<para>
|
|
Match lengths are measured in characters, not collating elements.
|
|
An empty string is considered longer than no match at all.
|
|
For example:
|
|
<literal>bb*</>
|
|
matches the three middle characters of <literal>abbbc</>;
|
|
<literal>(week|wee)(night|knights)</>
|
|
matches all ten characters of <literal>weeknights</>;
|
|
when <literal>(.*).*</>
|
|
is matched against <literal>abc</> the parenthesized subexpression
|
|
matches all three characters; and when
|
|
<literal>(a*)*</> is matched against <literal>bc</>
|
|
both the whole RE and the parenthesized
|
|
subexpression match an empty string.
|
|
</para>
|
|
|
|
<para>
|
|
If case-independent matching is specified,
|
|
the effect is much as if all case distinctions had vanished from the
|
|
alphabet.
|
|
When an alphabetic that exists in multiple cases appears as an
|
|
ordinary character outside a bracket expression, it is effectively
|
|
transformed into a bracket expression containing both cases,
|
|
e.g., <literal>x</> becomes <literal>[xX]</>.
|
|
When it appears inside a bracket expression, all case counterparts
|
|
of it are added to the bracket expression, e.g.,
|
|
<literal>[x]</> becomes <literal>[xX]</>
|
|
and <literal>[^x]</> becomes <literal>[^xX]</>.
|
|
</para>
|
|
|
|
<para>
|
|
If newline-sensitive matching is specified, <literal>.</>
|
|
and bracket expressions using <literal>^</>
|
|
will never match the newline character
|
|
(so that matches will never cross newlines unless the RE
|
|
explicitly arranges it)
|
|
and <literal>^</>and <literal>$</>
|
|
will match the empty string after and before a newline
|
|
respectively, in addition to matching at beginning and end of string
|
|
respectively.
|
|
But the ARE escapes <literal>\A</> and <literal>\Z</>
|
|
continue to match beginning or end of string <emphasis>only</>.
|
|
</para>
|
|
|
|
<para>
|
|
If partial newline-sensitive matching is specified,
|
|
this affects <literal>.</> and bracket expressions
|
|
as with newline-sensitive matching, but not <literal>^</>
|
|
and <literal>$</>.
|
|
</para>
|
|
|
|
<para>
|
|
If inverse partial newline-sensitive matching is specified,
|
|
this affects <literal>^</> and <literal>$</>
|
|
as with newline-sensitive matching, but not <literal>.</>
|
|
and bracket expressions.
|
|
This isn't very useful but is provided for symmetry.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="posix-limits-compatibility">
|
|
<title>Limits and Compatibility</title>
|
|
|
|
<para>
|
|
No particular limit is imposed on the length of REs in this
|
|
implementation. However,
|
|
programs intended to be highly portable should not employ REs longer
|
|
than 256 bytes,
|
|
as a POSIX-compliant implementation can refuse to accept such REs.
|
|
</para>
|
|
|
|
<para>
|
|
The only feature of AREs that is actually incompatible with
|
|
POSIX EREs is that <literal>\</> does not lose its special
|
|
significance inside bracket expressions.
|
|
All other ARE features use syntax which is illegal or has
|
|
undefined or unspecified effects in POSIX EREs;
|
|
the <literal>***</> syntax of directors likewise is outside the POSIX
|
|
syntax for both BREs and EREs.
|
|
</para>
|
|
|
|
<para>
|
|
Many of the ARE extensions are borrowed from Perl, but some have
|
|
been changed to clean them up, and a few Perl extensions are not present.
|
|
Incompatibilities of note include <literal>\b</>, <literal>\B</>,
|
|
the lack of special treatment for a trailing newline,
|
|
the addition of complemented bracket expressions to the things
|
|
affected by newline-sensitive matching,
|
|
the restrictions on parentheses and back references in lookahead
|
|
constraints, and the longest/shortest-match (rather than first-match)
|
|
matching semantics.
|
|
</para>
|
|
|
|
<para>
|
|
Two significant incompatibilities exist between AREs and the ERE syntax
|
|
recognized by pre-7.4 releases of <productname>PostgreSQL</>:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
In AREs, <literal>\</> followed by an alphanumeric character is either
|
|
an escape or an error, while in previous releases, it was just another
|
|
way of writing the alphanumeric.
|
|
This should not be much of a problem because there was no reason to
|
|
write such a sequence in earlier releases.
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
In AREs, <literal>\</> remains a special character within
|
|
<literal>[]</>, so a literal <literal>\</> within a bracket
|
|
expression must be written <literal>\\</>.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="posix-basic-regexes">
|
|
<title>Basic Regular Expressions</title>
|
|
|
|
<para>
|
|
BREs differ from EREs in several respects.
|
|
In BREs, <literal>|</>, <literal>+</>, and <literal>?</>
|
|
are ordinary characters and there is no equivalent
|
|
for their functionality.
|
|
The delimiters for bounds are
|
|
<literal>\{</> and <literal>\}</>,
|
|
with <literal>{</> and <literal>}</>
|
|
by themselves ordinary characters.
|
|
The parentheses for nested subexpressions are
|
|
<literal>\(</> and <literal>\)</>,
|
|
with <literal>(</> and <literal>)</> by themselves ordinary characters.
|
|
<literal>^</> is an ordinary character except at the beginning of the
|
|
RE or the beginning of a parenthesized subexpression,
|
|
<literal>$</> is an ordinary character except at the end of the
|
|
RE or the end of a parenthesized subexpression,
|
|
and <literal>*</> is an ordinary character if it appears at the beginning
|
|
of the RE or the beginning of a parenthesized subexpression
|
|
(after a possible leading <literal>^</>).
|
|
Finally, single-digit back references are available, and
|
|
<literal>\<</> and <literal>\></>
|
|
are synonyms for
|
|
<literal>[[:<:]]</> and <literal>[[:>:]]</>
|
|
respectively; no other escapes are available in BREs.
|
|
</para>
|
|
</sect3>
|
|
|
|
<!-- end re_syntax.n man page -->
|
|
|
|
</sect2>
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-formatting">
|
|
<title>Data Type Formatting Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>formatting</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The <productname>PostgreSQL</productname> formatting functions
|
|
provide a powerful set of tools for converting various data types
|
|
(date/time, integer, floating point, numeric) to formatted strings
|
|
and for converting from formatted strings to specific data types.
|
|
<xref linkend="functions-formatting-table"> lists them.
|
|
These functions all follow a common calling convention: the first
|
|
argument is the value to be formatted and the second argument is a
|
|
template that defines the output or input format.
|
|
</para>
|
|
<para>
|
|
A single-argument <function>to_timestamp</function> function is also
|
|
available; it accepts a
|
|
<type>double precision</type> argument and converts from Unix epoch
|
|
(seconds since 1970-01-01 00:00:00+00) to
|
|
<type>timestamp with time zone</type>.
|
|
(<type>Integer</type> Unix epochs are implicitly cast to
|
|
<type>double precision</type>.)
|
|
</para>
|
|
|
|
<table id="functions-formatting-table">
|
|
<title>Formatting Functions</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_char</primary>
|
|
</indexterm>
|
|
<literal><function>to_char(<type>timestamp</type>, <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>convert time stamp to string</entry>
|
|
<entry><literal>to_char(current_timestamp, 'HH12:MI:SS')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_char(<type>interval</type>, <type>text</type>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>convert interval to string</entry>
|
|
<entry><literal>to_char(interval '15h 2m 12s', 'HH24:MI:SS')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_char(<type>int</type>, <type>text</type>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>convert integer to string</entry>
|
|
<entry><literal>to_char(125, '999')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_char</function>(<type>double precision</type>,
|
|
<type>text</type>)</literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>convert real/double precision to string</entry>
|
|
<entry><literal>to_char(125.8::real, '999D9')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_char(<type>numeric</type>, <type>text</type>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>convert numeric to string</entry>
|
|
<entry><literal>to_char(-125.8, '999D99S')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_date</primary>
|
|
</indexterm>
|
|
<literal><function>to_date(<type>text</type>, <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>date</type></entry>
|
|
<entry>convert string to date</entry>
|
|
<entry><literal>to_date('05 Dec 2000', 'DD Mon YYYY')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_number</primary>
|
|
</indexterm>
|
|
<literal><function>to_number(<type>text</type>, <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>numeric</type></entry>
|
|
<entry>convert string to numeric</entry>
|
|
<entry><literal>to_number('12,454.8-', '99G999D9S')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_timestamp</primary>
|
|
</indexterm>
|
|
<literal><function>to_timestamp(<type>text</type>, <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>convert string to time stamp</entry>
|
|
<entry><literal>to_timestamp('05 Dec 2000', 'DD Mon YYYY')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>to_timestamp(<type>double precision</type>)</function></literal></entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>convert Unix epoch to time stamp</entry>
|
|
<entry><literal>to_timestamp(1284352323)</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
In a <function>to_char</> output template string, there are certain
|
|
patterns that are recognized and replaced with appropriately-formatted
|
|
data based on the given value. Any text that is not a template pattern is
|
|
simply copied verbatim. Similarly, in an input template string (for the
|
|
other functions), template patterns identify the values to be supplied by
|
|
the input data string.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-formatting-datetime-table"> shows the
|
|
template patterns available for formatting date and time values.
|
|
</para>
|
|
|
|
<table id="functions-formatting-datetime-table">
|
|
<title>Template Patterns for Date/Time Formatting</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Pattern</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>HH</literal></entry>
|
|
<entry>hour of day (01-12)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>HH12</literal></entry>
|
|
<entry>hour of day (01-12)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>HH24</literal></entry>
|
|
<entry>hour of day (00-23)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>MI</literal></entry>
|
|
<entry>minute (00-59)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>SS</literal></entry>
|
|
<entry>second (00-59)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>MS</literal></entry>
|
|
<entry>millisecond (000-999)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>US</literal></entry>
|
|
<entry>microsecond (000000-999999)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>SSSS</literal></entry>
|
|
<entry>seconds past midnight (0-86399)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>AM</literal>, <literal>am</literal>,
|
|
<literal>PM</literal> or <literal>pm</literal></entry>
|
|
<entry>meridiem indicator (without periods)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>A.M.</literal>, <literal>a.m.</literal>,
|
|
<literal>P.M.</literal> or <literal>p.m.</literal></entry>
|
|
<entry>meridiem indicator (with periods)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Y,YYY</literal></entry>
|
|
<entry>year (4 and more digits) with comma</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>YYYY</literal></entry>
|
|
<entry>year (4 and more digits)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>YYY</literal></entry>
|
|
<entry>last 3 digits of year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>YY</literal></entry>
|
|
<entry>last 2 digits of year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Y</literal></entry>
|
|
<entry>last digit of year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>IYYY</literal></entry>
|
|
<entry>ISO year (4 and more digits)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>IYY</literal></entry>
|
|
<entry>last 3 digits of ISO year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>IY</literal></entry>
|
|
<entry>last 2 digits of ISO year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>I</literal></entry>
|
|
<entry>last digit of ISO year</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>BC</literal>, <literal>bc</literal>,
|
|
<literal>AD</literal> or <literal>ad</literal></entry>
|
|
<entry>era indicator (without periods)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>B.C.</literal>, <literal>b.c.</literal>,
|
|
<literal>A.D.</literal> or <literal>a.d.</literal></entry>
|
|
<entry>era indicator (with periods)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>MONTH</literal></entry>
|
|
<entry>full upper case month name (blank-padded to 9 chars)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Month</literal></entry>
|
|
<entry>full capitalized month name (blank-padded to 9 chars)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>month</literal></entry>
|
|
<entry>full lower case month name (blank-padded to 9 chars)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>MON</literal></entry>
|
|
<entry>abbreviated upper case month name (3 chars in English, localized lengths vary)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Mon</literal></entry>
|
|
<entry>abbreviated capitalized month name (3 chars in English, localized lengths vary)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>mon</literal></entry>
|
|
<entry>abbreviated lower case month name (3 chars in English, localized lengths vary)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>MM</literal></entry>
|
|
<entry>month number (01-12)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>DAY</literal></entry>
|
|
<entry>full upper case day name (blank-padded to 9 chars)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Day</literal></entry>
|
|
<entry>full capitalized day name (blank-padded to 9 chars)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>day</literal></entry>
|
|
<entry>full lower case day name (blank-padded to 9 chars)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>DY</literal></entry>
|
|
<entry>abbreviated upper case day name (3 chars in English, localized lengths vary)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Dy</literal></entry>
|
|
<entry>abbreviated capitalized day name (3 chars in English, localized lengths vary)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>dy</literal></entry>
|
|
<entry>abbreviated lower case day name (3 chars in English, localized lengths vary)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>DDD</literal></entry>
|
|
<entry>day of year (001-366)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>IDDD</literal></entry>
|
|
<entry>ISO day of year (001-371; day 1 of the year is Monday of the first ISO week.)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>DD</literal></entry>
|
|
<entry>day of month (01-31)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>D</literal></entry>
|
|
<entry>day of the week, Sunday(<literal>1</>) to Saturday(<literal>7</>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>ID</literal></entry>
|
|
<entry>ISO day of the week, Monday(<literal>1</>) to Sunday(<literal>7</>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>W</literal></entry>
|
|
<entry>week of month (1-5) (The first week starts on the first day of the month.)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>WW</literal></entry>
|
|
<entry>week number of year (1-53) (The first week starts on the first day of the year.)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>IW</literal></entry>
|
|
<entry>ISO week number of year (01 - 53; the first Thursday of the new year is in week 1.)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>CC</literal></entry>
|
|
<entry>century (2 digits) (The twenty-first century starts on 2001-01-01.)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>J</literal></entry>
|
|
<entry>Julian Day (days since November 24, 4714 BC at midnight)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>Q</literal></entry>
|
|
<entry>quarter (ignored by <function>to_date</> and <function>to_timestamp</>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>RM</literal></entry>
|
|
<entry>month in upper case Roman numerals (I-XII; I=January)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>rm</literal></entry>
|
|
<entry>month in lower case Roman numerals (i-xii; i=January)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>TZ</literal></entry>
|
|
<entry>upper case time-zone name</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>tz</literal></entry>
|
|
<entry>lower case time-zone name</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Modifiers can be applied to any template pattern to alter its
|
|
behavior. For example, <literal>FMMonth</literal>
|
|
is the <literal>Month</literal> pattern with the
|
|
<literal>FM</literal> modifier.
|
|
<xref linkend="functions-formatting-datetimemod-table"> shows the
|
|
modifier patterns for date/time formatting.
|
|
</para>
|
|
|
|
<table id="functions-formatting-datetimemod-table">
|
|
<title>Template Pattern Modifiers for Date/Time Formatting</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Modifier</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>FM</literal> prefix</entry>
|
|
<entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
|
|
<entry><literal>FMMonth</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>TH</literal> suffix</entry>
|
|
<entry>upper case ordinal number suffix</entry>
|
|
<entry><literal>DDTH</literal>, e.g., <literal>12TH</></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>th</literal> suffix</entry>
|
|
<entry>lower case ordinal number suffix</entry>
|
|
<entry><literal>DDth</literal>, e.g., <literal>12th</></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>FX</literal> prefix</entry>
|
|
<entry>fixed format global option (see usage notes)</entry>
|
|
<entry><literal>FX Month DD Day</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>TM</literal> prefix</entry>
|
|
<entry>translation mode (print localized day and month names based on
|
|
<xref linkend="guc-lc-time">)</entry>
|
|
<entry><literal>TMMonth</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>SP</literal> suffix</entry>
|
|
<entry>spell mode (not implemented)</entry>
|
|
<entry><literal>DDSP</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Usage notes for date/time formatting:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
<literal>FM</literal> suppresses leading zeroes and trailing blanks
|
|
that would otherwise be added to make the output of a pattern be
|
|
fixed-width. In <productname>PostgreSQL</productname>,
|
|
<literal>FM</literal> modifies only the next specification, while in
|
|
Oracle <literal>FM</literal> affects all subsequent
|
|
specifications, and repeated <literal>FM</literal> modifiers
|
|
toggle fill mode on and off.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<literal>TM</literal> does not include trailing blanks.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<function>to_timestamp</function> and <function>to_date</function>
|
|
skip multiple blank spaces in the input string unless the
|
|
<literal>FX</literal> option is used. For example,
|
|
<literal>to_timestamp('2000 JUN', 'YYYY MON')</literal> works, but
|
|
<literal>to_timestamp('2000 JUN', 'FXYYYY MON')</literal> returns an error
|
|
because <function>to_timestamp</function> expects one space only.
|
|
<literal>FX</literal> must be specified as the first item in
|
|
the template.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
Ordinary text is allowed in <function>to_char</function>
|
|
templates and will be output literally. You can put a substring
|
|
in double quotes to force it to be interpreted as literal text
|
|
even if it contains pattern key words. For example, in
|
|
<literal>'"Hello Year "YYYY'</literal>, the <literal>YYYY</literal>
|
|
will be replaced by the year data, but the single <literal>Y</literal> in <literal>Year</literal>
|
|
will not be. In <function>to_date</>, <function>to_number</>,
|
|
and <function>to_timestamp</>, double-quoted strings skip the number of
|
|
input characters contained in the string, e.g. <literal>"XX"</>
|
|
skips two input characters.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
If you want to have a double quote in the output you must
|
|
precede it with a backslash, for example <literal>E'\\"YYYY
|
|
Month\\"'</literal>. <!-- "" font-lock sanity :-) -->
|
|
(Two backslashes are necessary because the backslash
|
|
has special meaning when using the escape string syntax.)
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
The <literal>YYYY</literal> conversion from string to <type>timestamp</type> or
|
|
<type>date</type> has a restriction when processing years with more than 4 digits. You must
|
|
use some non-digit character or template after <literal>YYYY</literal>,
|
|
otherwise the year is always interpreted as 4 digits. For example
|
|
(with the year 20000):
|
|
<literal>to_date('200001131', 'YYYYMMDD')</literal> will be
|
|
interpreted as a 4-digit year; instead use a non-digit
|
|
separator after the year, like
|
|
<literal>to_date('20000-1131', 'YYYY-MMDD')</literal> or
|
|
<literal>to_date('20000Nov31', 'YYYYMonDD')</literal>.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In conversions from string to <type>timestamp</type> or
|
|
<type>date</type>, the <literal>CC</literal> (century) field is ignored
|
|
if there is a <literal>YYY</literal>, <literal>YYYY</literal> or
|
|
<literal>Y,YYY</literal> field. If <literal>CC</literal> is used with
|
|
<literal>YY</literal> or <literal>Y</literal> then the year is computed
|
|
as <literal>(CC-1)*100+YY</literal>.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
An ISO week date (as distinct from a Gregorian date) can be
|
|
specified to <function>to_timestamp</function> and
|
|
<function>to_date</function> in one of two ways:
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
Year, week, and weekday: for example <literal>to_date('2006-42-4',
|
|
'IYYY-IW-ID')</literal> returns the date
|
|
<literal>2006-10-19</literal>. If you omit the weekday it
|
|
is assumed to be 1 (Monday).
|
|
</para>
|
|
</listitem>
|
|
<listitem>
|
|
<para>
|
|
Year and day of year: for example <literal>to_date('2006-291',
|
|
'IYYY-IDDD')</literal> also returns <literal>2006-10-19</literal>.
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
<para>
|
|
Attempting to construct a date using a mixture of ISO week and
|
|
Gregorian date fields is nonsensical, and will cause an error. In the
|
|
context of an ISO year, the concept of a <quote>month</> or <quote>day
|
|
of month</> has no meaning. In the context of a Gregorian year, the
|
|
ISO week has no meaning. Users should avoid mixing Gregorian and
|
|
ISO date specifications.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
In a conversion from string to <type>timestamp</type>, millisecond
|
|
(<literal>MS</literal>) or microsecond (<literal>US</literal>)
|
|
values are used as the
|
|
seconds digits after the decimal point. For example
|
|
<literal>to_timestamp('12:3', 'SS:MS')</literal> is not 3 milliseconds,
|
|
but 300, because the conversion counts it as 12 + 0.3 seconds.
|
|
This means for the format <literal>SS:MS</literal>, the input values
|
|
<literal>12:3</literal>, <literal>12:30</literal>, and <literal>12:300</literal> specify the
|
|
same number of milliseconds. To get three milliseconds, one must use
|
|
<literal>12:003</literal>, which the conversion counts as
|
|
12 + 0.003 = 12.003 seconds.
|
|
</para>
|
|
|
|
<para>
|
|
Here is a more
|
|
complex example:
|
|
<literal>to_timestamp('15:12:02.020.001230', 'HH:MI:SS.MS.US')</literal>
|
|
is 15 hours, 12 minutes, and 2 seconds + 20 milliseconds +
|
|
1230 microseconds = 2.021230 seconds.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<function>to_char(..., 'ID')</function>'s day of the week numbering
|
|
matches the <function>extract(isodow from ...)</function> function, but
|
|
<function>to_char(..., 'D')</function>'s does not match
|
|
<function>extract(dow from ...)</function>'s day numbering.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<function>to_char(interval)</function> formats <literal>HH</> and
|
|
<literal>HH12</> as shown on a 12-hour clock, i.e. zero hours
|
|
and 36 hours output as <literal>12</>, while <literal>HH24</>
|
|
outputs the full hour value, which can exceed 23 for intervals.
|
|
</para>
|
|
</listitem>
|
|
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-formatting-numeric-table"> shows the
|
|
template patterns available for formatting numeric values.
|
|
</para>
|
|
|
|
<table id="functions-formatting-numeric-table">
|
|
<title>Template Patterns for Numeric Formatting</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Pattern</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>9</literal></entry>
|
|
<entry>value with the specified number of digits</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>0</literal></entry>
|
|
<entry>value with leading zeros</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>.</literal> (period)</entry>
|
|
<entry>decimal point</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>,</literal> (comma)</entry>
|
|
<entry>group (thousand) separator</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>PR</literal></entry>
|
|
<entry>negative value in angle brackets</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>S</literal></entry>
|
|
<entry>sign anchored to number (uses locale)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>L</literal></entry>
|
|
<entry>currency symbol (uses locale)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>D</literal></entry>
|
|
<entry>decimal point (uses locale)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>G</literal></entry>
|
|
<entry>group separator (uses locale)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>MI</literal></entry>
|
|
<entry>minus sign in specified position (if number < 0)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>PL</literal></entry>
|
|
<entry>plus sign in specified position (if number > 0)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>SG</literal></entry>
|
|
<entry>plus/minus sign in specified position</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>RN</literal></entry>
|
|
<entry>Roman numeral (input between 1 and 3999)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>TH</literal> or <literal>th</literal></entry>
|
|
<entry>ordinal number suffix</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>V</literal></entry>
|
|
<entry>shift specified number of digits (see notes)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>EEEE</literal></entry>
|
|
<entry>exponent for scientific notation</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Usage notes for numeric formatting:
|
|
|
|
<itemizedlist>
|
|
<listitem>
|
|
<para>
|
|
A sign formatted using <literal>SG</literal>, <literal>PL</literal>, or
|
|
<literal>MI</literal> is not anchored to
|
|
the number; for example,
|
|
<literal>to_char(-12, 'MI9999')</literal> produces <literal>'- 12'</literal>
|
|
but <literal>to_char(-12, 'S9999')</literal> produces <literal>' -12'</literal>.
|
|
The Oracle implementation does not allow the use of
|
|
<literal>MI</literal> before <literal>9</literal>, but rather
|
|
requires that <literal>9</literal> precede
|
|
<literal>MI</literal>.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<literal>9</literal> results in a value with the same number of
|
|
digits as there are <literal>9</literal>s. If a digit is
|
|
not available it outputs a space.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<literal>TH</literal> does not convert values less than zero
|
|
and does not convert fractional numbers.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<literal>PL</literal>, <literal>SG</literal>, and
|
|
<literal>TH</literal> are <productname>PostgreSQL</productname>
|
|
extensions.
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<literal>V</literal> effectively
|
|
multiplies the input values by
|
|
<literal>10^<replaceable>n</replaceable></literal>, where
|
|
<replaceable>n</replaceable> is the number of digits following
|
|
<literal>V</literal>.
|
|
<function>to_char</function> does not support the use of
|
|
<literal>V</literal> combined with a decimal point
|
|
(e.g., <literal>99.9V99</literal> is not allowed).
|
|
</para>
|
|
</listitem>
|
|
|
|
<listitem>
|
|
<para>
|
|
<literal>EEEE</literal> (scientific notation) cannot be used in
|
|
combination with any of the other formatting patterns or
|
|
modifiers other than digit and decimal point patterns, and must be at the end of the format string
|
|
(e.g., <literal>9.99EEEE</literal> is a valid pattern).
|
|
</para>
|
|
</listitem>
|
|
</itemizedlist>
|
|
</para>
|
|
|
|
<para>
|
|
Certain modifiers can be applied to any template pattern to alter its
|
|
behavior. For example, <literal>FM9999</literal>
|
|
is the <literal>9999</literal> pattern with the
|
|
<literal>FM</literal> modifier.
|
|
<xref linkend="functions-formatting-numericmod-table"> shows the
|
|
modifier patterns for numeric formatting.
|
|
</para>
|
|
|
|
<table id="functions-formatting-numericmod-table">
|
|
<title>Template Pattern Modifiers for Numeric Formatting</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Modifier</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>FM</literal> prefix</entry>
|
|
<entry>fill mode (suppress padding blanks and trailing zeroes)</entry>
|
|
<entry><literal>FM9999</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>TH</literal> suffix</entry>
|
|
<entry>upper case ordinal number suffix</entry>
|
|
<entry><literal>999TH</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>th</literal> suffix</entry>
|
|
<entry>lower case ordinal number suffix</entry>
|
|
<entry><literal>999th</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<xref linkend="functions-formatting-examples-table"> shows some
|
|
examples of the use of the <function>to_char</function> function.
|
|
</para>
|
|
|
|
<table id="functions-formatting-examples-table">
|
|
<title><function>to_char</function> Examples</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Expression</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal>to_char(current_timestamp, 'Day, DD HH12:MI:SS')</literal></entry>
|
|
<entry><literal>'Tuesday , 06 05:39:18'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(current_timestamp, 'FMDay, FMDD HH12:MI:SS')</literal></entry>
|
|
<entry><literal>'Tuesday, 6 05:39:18'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-0.1, '99.99')</literal></entry>
|
|
<entry><literal>' -.10'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-0.1, 'FM9.99')</literal></entry>
|
|
<entry><literal>'-.1'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(0.1, '0.9')</literal></entry>
|
|
<entry><literal>' 0.1'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(12, '9990999.9')</literal></entry>
|
|
<entry><literal>' 0012.0'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(12, 'FM9990999.9')</literal></entry>
|
|
<entry><literal>'0012.'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, '999')</literal></entry>
|
|
<entry><literal>' 485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-485, '999')</literal></entry>
|
|
<entry><literal>'-485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, '9 9 9')</literal></entry>
|
|
<entry><literal>' 4 8 5'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(1485, '9,999')</literal></entry>
|
|
<entry><literal>' 1,485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(1485, '9G999')</literal></entry>
|
|
<entry><literal>' 1 485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(148.5, '999.999')</literal></entry>
|
|
<entry><literal>' 148.500'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(148.5, 'FM999.999')</literal></entry>
|
|
<entry><literal>'148.5'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(148.5, 'FM999.990')</literal></entry>
|
|
<entry><literal>'148.500'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(148.5, '999D999')</literal></entry>
|
|
<entry><literal>' 148,500'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(3148.5, '9G999D999')</literal></entry>
|
|
<entry><literal>' 3 148,500'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-485, '999S')</literal></entry>
|
|
<entry><literal>'485-'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-485, '999MI')</literal></entry>
|
|
<entry><literal>'485-'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, '999MI')</literal></entry>
|
|
<entry><literal>'485 '</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, 'FM999MI')</literal></entry>
|
|
<entry><literal>'485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, 'PL999')</literal></entry>
|
|
<entry><literal>'+485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, 'SG999')</literal></entry>
|
|
<entry><literal>'+485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-485, 'SG999')</literal></entry>
|
|
<entry><literal>'-485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-485, '9SG99')</literal></entry>
|
|
<entry><literal>'4-85'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(-485, '999PR')</literal></entry>
|
|
<entry><literal>'<485>'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, 'L999')</literal></entry>
|
|
<entry><literal>'DM 485</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, 'RN')</literal></entry>
|
|
<entry><literal>' CDLXXXV'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, 'FMRN')</literal></entry>
|
|
<entry><literal>'CDLXXXV'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(5.2, 'FMRN')</literal></entry>
|
|
<entry><literal>'V'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(482, '999th')</literal></entry>
|
|
<entry><literal>' 482nd'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485, '"Good number:"999')</literal></entry>
|
|
<entry><literal>'Good number: 485'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(485.8, '"Pre:"999" Post:" .999')</literal></entry>
|
|
<entry><literal>'Pre: 485 Post: .800'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(12, '99V999')</literal></entry>
|
|
<entry><literal>' 12000'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(12.4, '99V999')</literal></entry>
|
|
<entry><literal>' 12400'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(12.45, '99V9')</literal></entry>
|
|
<entry><literal>' 125'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>to_char(0.0004859, '9.99EEEE')</literal></entry>
|
|
<entry><literal>' 4.86e-04'</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-datetime">
|
|
<title>Date/Time Functions and Operators</title>
|
|
|
|
<para>
|
|
<xref linkend="functions-datetime-table"> shows the available
|
|
functions for date/time value processing, with details appearing in
|
|
the following subsections. <xref
|
|
linkend="operators-datetime-table"> illustrates the behaviors of
|
|
the basic arithmetic operators (<literal>+</literal>,
|
|
<literal>*</literal>, etc.). For formatting functions, refer to
|
|
<xref linkend="functions-formatting">. You should be familiar with
|
|
the background information on date/time data types from <xref
|
|
linkend="datatype-datetime">.
|
|
</para>
|
|
|
|
<para>
|
|
All the functions and operators described below that take <type>time</type> or <type>timestamp</type>
|
|
inputs actually come in two variants: one that takes <type>time with time zone</type> or <type>timestamp
|
|
with time zone</type>, and one that takes <type>time without time zone</type> or <type>timestamp without time zone</type>.
|
|
For brevity, these variants are not shown separately. Also, the
|
|
<literal>+</> and <literal>*</> operators come in commutative pairs (for
|
|
example both date + integer and integer + date); we show only one of each
|
|
such pair.
|
|
</para>
|
|
|
|
<table id="operators-datetime-table">
|
|
<title>Date/Time Operators</title>
|
|
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry><literal>date '2001-09-28' + integer '7'</literal></entry>
|
|
<entry><literal>date '2001-10-05'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry><literal>date '2001-09-28' + interval '1 hour'</literal></entry>
|
|
<entry><literal>timestamp '2001-09-28 01:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry><literal>date '2001-09-28' + time '03:00'</literal></entry>
|
|
<entry><literal>timestamp '2001-09-28 03:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry><literal>interval '1 day' + interval '1 hour'</literal></entry>
|
|
<entry><literal>interval '1 day 01:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry><literal>timestamp '2001-09-28 01:00' + interval '23 hours'</literal></entry>
|
|
<entry><literal>timestamp '2001-09-29 00:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry><literal>time '01:00' + interval '3 hours'</literal></entry>
|
|
<entry><literal>time '04:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>- interval '23 hours'</literal></entry>
|
|
<entry><literal>interval '-23:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>date '2001-10-01' - date '2001-09-28'</literal></entry>
|
|
<entry><literal>integer '3'</literal> (days)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>date '2001-10-01' - integer '7'</literal></entry>
|
|
<entry><literal>date '2001-09-24'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>date '2001-09-28' - interval '1 hour'</literal></entry>
|
|
<entry><literal>timestamp '2001-09-27 23:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>time '05:00' - time '03:00'</literal></entry>
|
|
<entry><literal>interval '02:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>time '05:00' - interval '2 hours'</literal></entry>
|
|
<entry><literal>time '03:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>timestamp '2001-09-28 23:00' - interval '23 hours'</literal></entry>
|
|
<entry><literal>timestamp '2001-09-28 00:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>interval '1 day' - interval '1 hour'</literal></entry>
|
|
<entry><literal>interval '1 day -01:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry><literal>timestamp '2001-09-29 03:00' - timestamp '2001-09-27 12:00'</literal></entry>
|
|
<entry><literal>interval '1 day 15:00:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>*</literal> </entry>
|
|
<entry><literal>900 * interval '1 second'</literal></entry>
|
|
<entry><literal>interval '00:15:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>*</literal> </entry>
|
|
<entry><literal>21 * interval '1 day'</literal></entry>
|
|
<entry><literal>interval '21 days'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>*</literal> </entry>
|
|
<entry><literal>double precision '3.5' * interval '1 hour'</literal></entry>
|
|
<entry><literal>interval '03:30:00'</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>/</literal> </entry>
|
|
<entry><literal>interval '1 hour' / double precision '1.5'</literal></entry>
|
|
<entry><literal>interval '00:40:00'</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<table id="functions-datetime-table">
|
|
<title>Date/Time Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>age</primary>
|
|
</indexterm>
|
|
<literal><function>age(<type>timestamp</type>, <type>timestamp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>interval</type></entry>
|
|
<entry>Subtract arguments, producing a <quote>symbolic</> result that
|
|
uses years and months</entry>
|
|
<entry><literal>age(timestamp '2001-04-10', timestamp '1957-06-13')</literal></entry>
|
|
<entry><literal>43 years 9 mons 27 days</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>age(<type>timestamp</type>)</function></literal></entry>
|
|
<entry><type>interval</type></entry>
|
|
<entry>Subtract from <function>current_date</function> (at midnight)</entry>
|
|
<entry><literal>age(timestamp '1957-06-13')</literal></entry>
|
|
<entry><literal>43 years 8 mons 3 days</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>clock_timestamp</primary>
|
|
</indexterm>
|
|
<literal><function>clock_timestamp()</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Current date and time (changes during statement execution);
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>current_date</primary>
|
|
</indexterm>
|
|
<literal><function>current_date</function></literal>
|
|
</entry>
|
|
<entry><type>date</type></entry>
|
|
<entry>Current date;
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>current_time</primary>
|
|
</indexterm>
|
|
<literal><function>current_time</function></literal>
|
|
</entry>
|
|
<entry><type>time with time zone</type></entry>
|
|
<entry>Current time of day;
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>current_timestamp</primary>
|
|
</indexterm>
|
|
<literal><function>current_timestamp</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Current date and time (start of current transaction);
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>date_part</primary>
|
|
</indexterm>
|
|
<literal><function>date_part(<type>text</type>, <type>timestamp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>Get subfield (equivalent to <function>extract</function>);
|
|
see <xref linkend="functions-datetime-extract">
|
|
</entry>
|
|
<entry><literal>date_part('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
|
|
<entry><literal>20</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>date_part(<type>text</type>, <type>interval</type>)</function></literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>Get subfield (equivalent to
|
|
<function>extract</function>); see <xref linkend="functions-datetime-extract">
|
|
</entry>
|
|
<entry><literal>date_part('month', interval '2 years 3 months')</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>date_trunc</primary>
|
|
</indexterm>
|
|
<literal><function>date_trunc(<type>text</type>, <type>timestamp</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp</type></entry>
|
|
<entry>Truncate to specified precision; see also <xref linkend="functions-datetime-trunc">
|
|
</entry>
|
|
<entry><literal>date_trunc('hour', timestamp '2001-02-16 20:38:40')</literal></entry>
|
|
<entry><literal>2001-02-16 20:00:00</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>extract</primary>
|
|
</indexterm>
|
|
<literal><function>extract</function>(<parameter>field</parameter> from
|
|
<type>timestamp</type>)</literal>
|
|
</entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>Get subfield; see <xref linkend="functions-datetime-extract">
|
|
</entry>
|
|
<entry><literal>extract(hour from timestamp '2001-02-16 20:38:40')</literal></entry>
|
|
<entry><literal>20</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>extract</function>(<parameter>field</parameter> from
|
|
<type>interval</type>)</literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>Get subfield; see <xref linkend="functions-datetime-extract">
|
|
</entry>
|
|
<entry><literal>extract(month from interval '2 years 3 months')</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>isfinite</primary>
|
|
</indexterm>
|
|
<literal><function>isfinite(<type>date</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Test for finite date (not +/-infinity)</entry>
|
|
<entry><literal>isfinite(date '2001-02-16')</literal></entry>
|
|
<entry><literal>true</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>isfinite(<type>timestamp</type>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Test for finite time stamp (not +/-infinity)</entry>
|
|
<entry><literal>isfinite(timestamp '2001-02-16 21:28:30')</literal></entry>
|
|
<entry><literal>true</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>isfinite(<type>interval</type>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Test for finite interval</entry>
|
|
<entry><literal>isfinite(interval '4 hours')</literal></entry>
|
|
<entry><literal>true</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>justify_days</primary>
|
|
</indexterm>
|
|
<literal><function>justify_days(<type>interval</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>interval</type></entry>
|
|
<entry>Adjust interval so 30-day time periods are represented as months</entry>
|
|
<entry><literal>justify_days(interval '35 days')</literal></entry>
|
|
<entry><literal>1 mon 5 days</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>justify_hours</primary>
|
|
</indexterm>
|
|
<literal><function>justify_hours(<type>interval</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>interval</type></entry>
|
|
<entry>Adjust interval so 24-hour time periods are represented as days</entry>
|
|
<entry><literal>justify_hours(interval '27 hours')</literal></entry>
|
|
<entry><literal>1 day 03:00:00</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>justify_interval</primary>
|
|
</indexterm>
|
|
<literal><function>justify_interval(<type>interval</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>interval</type></entry>
|
|
<entry>Adjust interval using <function>justify_days</> and <function>justify_hours</>, with additional sign adjustments</entry>
|
|
<entry><literal>justify_interval(interval '1 mon -1 hour')</literal></entry>
|
|
<entry><literal>29 days 23:00:00</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>localtime</primary>
|
|
</indexterm>
|
|
<literal><function>localtime</function></literal>
|
|
</entry>
|
|
<entry><type>time</type></entry>
|
|
<entry>Current time of day;
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>localtimestamp</primary>
|
|
</indexterm>
|
|
<literal><function>localtimestamp</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp</type></entry>
|
|
<entry>Current date and time (start of current transaction);
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>now</primary>
|
|
</indexterm>
|
|
<literal><function>now()</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Current date and time (start of current transaction);
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>statement_timestamp</primary>
|
|
</indexterm>
|
|
<literal><function>statement_timestamp()</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Current date and time (start of current statement);
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>timeofday</primary>
|
|
</indexterm>
|
|
<literal><function>timeofday()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Current date and time
|
|
(like <function>clock_timestamp</>, but as a <type>text</> string);
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>transaction_timestamp</primary>
|
|
</indexterm>
|
|
<literal><function>transaction_timestamp()</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Current date and time (start of current transaction);
|
|
see <xref linkend="functions-datetime-current">
|
|
</entry>
|
|
<entry></entry>
|
|
<entry></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
In addition to these functions, the SQL <literal>OVERLAPS</> operator is
|
|
supported:
|
|
<synopsis>
|
|
(<replaceable>start1</replaceable>, <replaceable>end1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>end2</replaceable>)
|
|
(<replaceable>start1</replaceable>, <replaceable>length1</replaceable>) OVERLAPS (<replaceable>start2</replaceable>, <replaceable>length2</replaceable>)
|
|
</synopsis>
|
|
This expression yields true when two time periods (defined by their
|
|
endpoints) overlap, false when they do not overlap. The endpoints
|
|
can be specified as pairs of dates, times, or time stamps; or as
|
|
a date, time, or time stamp followed by an interval. When a pair
|
|
of values is provided, either the start or the end can be written
|
|
first; <literal>OVERLAPS</> automatically takes the earlier value
|
|
of the pair as the start. Each time period is considered to
|
|
represent the half-open interval <replaceable>start</> <literal><=</>
|
|
<replaceable>time</> <literal><</> <replaceable>end</>, unless
|
|
<replaceable>start</> and <replaceable>end</> are equal in which case it
|
|
represents that single time instant. This means for instance that two
|
|
time periods with only an endpoint in common do not overlap.
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT (DATE '2001-02-16', DATE '2001-12-21') OVERLAPS
|
|
(DATE '2001-10-30', DATE '2002-10-30');
|
|
<lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
|
|
SELECT (DATE '2001-02-16', INTERVAL '100 days') OVERLAPS
|
|
(DATE '2001-10-30', DATE '2002-10-30');
|
|
<lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
|
|
SELECT (DATE '2001-10-29', DATE '2001-10-30') OVERLAPS
|
|
(DATE '2001-10-30', DATE '2001-10-31');
|
|
<lineannotation>Result: </lineannotation><computeroutput>false</computeroutput>
|
|
SELECT (DATE '2001-10-30', DATE '2001-10-30') OVERLAPS
|
|
(DATE '2001-10-30', DATE '2001-10-31');
|
|
<lineannotation>Result: </lineannotation><computeroutput>true</computeroutput>
|
|
</screen>
|
|
|
|
<para>
|
|
When adding an <type>interval</type> value to (or subtracting an
|
|
<type>interval</type> value from) a <type>timestamp with time zone</type>
|
|
value, the days component advances (or decrements) the date of the
|
|
<type>timestamp with time zone</type> by the indicated number of days.
|
|
Across daylight saving time changes (with the session time zone set to a
|
|
time zone that recognizes DST), this means <literal>interval '1 day'</literal>
|
|
does not necessarily equal <literal>interval '24 hours'</literal>.
|
|
For example, with the session time zone set to <literal>CST7CDT</literal>,
|
|
<literal>timestamp with time zone '2005-04-02 12:00-07' + interval '1 day' </literal>
|
|
will produce <literal>timestamp with time zone '2005-04-03 12:00-06'</literal>,
|
|
while adding <literal>interval '24 hours'</literal> to the same initial
|
|
<type>timestamp with time zone</type> produces
|
|
<literal>timestamp with time zone '2005-04-03 13:00-06'</literal>, as there is
|
|
a change in daylight saving time at <literal>2005-04-03 02:00</literal> in time zone
|
|
<literal>CST7CDT</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Note there can be ambiguity in the <literal>months</> returned by
|
|
<function>age</> because different months have a different number of
|
|
days. <productname>PostgreSQL</>'s approach uses the month from the
|
|
earlier of the two dates when calculating partial months. For example,
|
|
<literal>age('2004-06-01', '2004-04-30')</> uses April to yield
|
|
<literal>1 mon 1 day</>, while using May would yield <literal>1 mon 2
|
|
days</> because May has 31 days, while April has only 30.
|
|
</para>
|
|
|
|
<sect2 id="functions-datetime-extract">
|
|
<title><function>EXTRACT</function>, <function>date_part</function></title>
|
|
|
|
<indexterm>
|
|
<primary>date_part</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>extract</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
EXTRACT(<replaceable>field</replaceable> FROM <replaceable>source</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>extract</function> function retrieves subfields
|
|
such as year or hour from date/time values.
|
|
<replaceable>source</replaceable> must be a value expression of
|
|
type <type>timestamp</type>, <type>time</type>, or <type>interval</type>.
|
|
(Expressions of type <type>date</type> are
|
|
cast to <type>timestamp</type> and can therefore be used as
|
|
well.) <replaceable>field</replaceable> is an identifier or
|
|
string that selects what field to extract from the source value.
|
|
The <function>extract</function> function returns values of type
|
|
<type>double precision</type>.
|
|
The following are valid field names:
|
|
|
|
<!-- alphabetical -->
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><literal>century</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The century
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2000-12-16 12:21:13');
|
|
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
|
|
SELECT EXTRACT(CENTURY FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>21</computeroutput>
|
|
</screen>
|
|
|
|
<para>
|
|
The first century starts at 0001-01-01 00:00:00 AD, although
|
|
they did not know it at the time. This definition applies to all
|
|
Gregorian calendar countries. There is no century number 0,
|
|
you go from -1 century to 1 century.
|
|
|
|
If you disagree with this, please write your complaint to:
|
|
Pope, Cathedral Saint-Peter of Roma, Vatican.
|
|
</para>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> releases before 8.0 did not
|
|
follow the conventional numbering of centuries, but just returned
|
|
the year field divided by 100.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>day</literal></term>
|
|
<listitem>
|
|
<para>
|
|
For <type>timestamp</type> values, the day (of the month) field
|
|
(1 - 31) ; for <type>interval</type> values, the number of days
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(DAY FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
|
|
|
|
SELECT EXTRACT(DAY FROM INTERVAL '40 days 1 minute');
|
|
<lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
|
|
</screen>
|
|
|
|
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>decade</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The year field divided by 10
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(DECADE FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>200</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>dow</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The day of the week as Sunday(<literal>0</>) to
|
|
Saturday(<literal>6</>)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(DOW FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>5</computeroutput>
|
|
</screen>
|
|
<para>
|
|
Note that <function>extract</function>'s day of the week numbering
|
|
differs from that of the <function>to_char(...,
|
|
'D')</function> function.
|
|
</para>
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>doy</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The day of the year (1 - 365/366)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(DOY FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>47</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>epoch</literal></term>
|
|
<listitem>
|
|
<para>
|
|
For <type>date</type> and <type>timestamp</type> values, the
|
|
number of seconds since 1970-01-01 00:00:00 UTC (can be negative);
|
|
for <type>interval</type> values, the total number
|
|
of seconds in the interval
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(EPOCH FROM TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40.12-08');
|
|
<lineannotation>Result: </lineannotation><computeroutput>982384720.12</computeroutput>
|
|
|
|
SELECT EXTRACT(EPOCH FROM INTERVAL '5 days 3 hours');
|
|
<lineannotation>Result: </lineannotation><computeroutput>442800</computeroutput>
|
|
</screen>
|
|
|
|
<para>
|
|
Here is how you can convert an epoch value back to a time
|
|
stamp:
|
|
</para>
|
|
<screen>
|
|
SELECT TIMESTAMP WITH TIME ZONE 'epoch' + 982384720.12 * INTERVAL '1 second';
|
|
</screen>
|
|
<para>
|
|
(The <function>to_timestamp</> function encapsulates the above
|
|
conversion.)
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>hour</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The hour field (0 - 23)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(HOUR FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>20</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>isodow</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The day of the week as Monday(<literal>1</>) to
|
|
Sunday(<literal>7</>)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(ISODOW FROM TIMESTAMP '2001-02-18 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
|
|
</screen>
|
|
<para>
|
|
This is identical to <literal>dow</> except for Sunday. This
|
|
matches the <acronym>ISO</> 8601 day of the week numbering.
|
|
</para>
|
|
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>isoyear</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The <acronym>ISO</acronym> 8601 year that the date falls in (not applicable to intervals)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-01');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2005</computeroutput>
|
|
SELECT EXTRACT(ISOYEAR FROM DATE '2006-01-02');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2006</computeroutput>
|
|
</screen>
|
|
|
|
<para>
|
|
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.
|
|
</para>
|
|
<para>
|
|
This field is not available in PostgreSQL releases prior to 8.3.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>microseconds</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The seconds field, including fractional parts, multiplied by 1
|
|
000 000; note that this includes full seconds
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(MICROSECONDS FROM TIME '17:12:28.5');
|
|
<lineannotation>Result: </lineannotation><computeroutput>28500000</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>millennium</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The millennium
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(MILLENNIUM FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
|
|
</screen>
|
|
|
|
<para>
|
|
Years in the 1900s are in the second millennium.
|
|
The third millennium started January 1, 2001.
|
|
</para>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> releases before 8.0 did not
|
|
follow the conventional numbering of millennia, but just returned
|
|
the year field divided by 1000.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>milliseconds</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The seconds field, including fractional parts, multiplied by
|
|
1000. Note that this includes full seconds.
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(MILLISECONDS FROM TIME '17:12:28.5');
|
|
<lineannotation>Result: </lineannotation><computeroutput>28500</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>minute</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The minutes field (0 - 59)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(MINUTE FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>38</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>month</literal></term>
|
|
<listitem>
|
|
<para>
|
|
For <type>timestamp</type> values, the number of the month
|
|
within the year (1 - 12) ; for <type>interval</type> values,
|
|
the number of months, modulo 12 (0 - 11)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(MONTH FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2</computeroutput>
|
|
|
|
SELECT EXTRACT(MONTH FROM INTERVAL '2 years 3 months');
|
|
<lineannotation>Result: </lineannotation><computeroutput>3</computeroutput>
|
|
|
|
SELECT EXTRACT(MONTH FROM INTERVAL '2 years 13 months');
|
|
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>quarter</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The quarter of the year (1 - 4) that the date is in
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(QUARTER FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>1</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>second</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The seconds field, including fractional parts (0 -
|
|
59<footnote><simpara>60 if leap seconds are
|
|
implemented by the operating system</simpara></footnote>)
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(SECOND FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>40</computeroutput>
|
|
|
|
SELECT EXTRACT(SECOND FROM TIME '17:12:28.5');
|
|
<lineannotation>Result: </lineannotation><computeroutput>28.5</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
<varlistentry>
|
|
<term><literal>timezone</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The time zone offset from UTC, measured in seconds. Positive values
|
|
correspond to time zones east of UTC, negative values to
|
|
zones west of UTC.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>timezone_hour</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The hour component of the time zone offset
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>timezone_minute</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The minute component of the time zone offset
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>week</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The number of the week of the year that the day is in. By definition
|
|
(<acronym>ISO</acronym> 8601), the first week of a year
|
|
contains January 4 of that year. (The <acronym>ISO</acronym>-8601
|
|
week starts on Monday.) In other words, the first Thursday of
|
|
a year is in week 1 of that year.
|
|
</para>
|
|
<para>
|
|
Because of this, it is possible for early January dates to be part of the
|
|
52nd or 53rd week of the previous year. For example, <literal>2005-01-01</>
|
|
is part of the 53rd week of year 2004, and <literal>2006-01-01</> is part of
|
|
the 52nd week of year 2005.
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(WEEK FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>7</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><literal>year</literal></term>
|
|
<listitem>
|
|
<para>
|
|
The year field. Keep in mind there is no <literal>0 AD</>, so subtracting
|
|
<literal>BC</> years from <literal>AD</> years should be done with care.
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT EXTRACT(YEAR FROM TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001</computeroutput>
|
|
</screen>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
The <function>extract</function> function is primarily intended
|
|
for computational processing. For formatting date/time values for
|
|
display, see <xref linkend="functions-formatting">.
|
|
</para>
|
|
|
|
<para>
|
|
The <function>date_part</function> function is modeled on the traditional
|
|
<productname>Ingres</productname> equivalent to the
|
|
<acronym>SQL</acronym>-standard function <function>extract</function>:
|
|
<synopsis>
|
|
date_part('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
|
|
</synopsis>
|
|
Note that here the <replaceable>field</replaceable> parameter needs to
|
|
be a string value, not a name. The valid field names for
|
|
<function>date_part</function> are the same as for
|
|
<function>extract</function>.
|
|
</para>
|
|
|
|
<screen>
|
|
SELECT date_part('day', TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>16</computeroutput>
|
|
|
|
SELECT date_part('hour', INTERVAL '4 hours 3 minutes');
|
|
<lineannotation>Result: </lineannotation><computeroutput>4</computeroutput>
|
|
</screen>
|
|
|
|
</sect2>
|
|
|
|
<sect2 id="functions-datetime-trunc">
|
|
<title><function>date_trunc</function></title>
|
|
|
|
<indexterm>
|
|
<primary>date_trunc</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The function <function>date_trunc</function> is conceptually
|
|
similar to the <function>trunc</function> function for numbers.
|
|
</para>
|
|
|
|
<para>
|
|
<synopsis>
|
|
date_trunc('<replaceable>field</replaceable>', <replaceable>source</replaceable>)
|
|
</synopsis>
|
|
<replaceable>source</replaceable> is a value expression of type
|
|
<type>timestamp</type> or <type>interval</>.
|
|
(Values of type <type>date</type> and
|
|
<type>time</type> are cast automatically to <type>timestamp</type> or
|
|
<type>interval</>, respectively.)
|
|
<replaceable>field</replaceable> selects to which precision to
|
|
truncate the input value. The return value is of type
|
|
<type>timestamp</type> or <type>interval</>
|
|
with all fields that are less significant than the
|
|
selected one set to zero (or one, for day and month).
|
|
</para>
|
|
|
|
<para>
|
|
Valid values for <replaceable>field</replaceable> are:
|
|
<simplelist>
|
|
<member><literal>microseconds</literal></member>
|
|
<member><literal>milliseconds</literal></member>
|
|
<member><literal>second</literal></member>
|
|
<member><literal>minute</literal></member>
|
|
<member><literal>hour</literal></member>
|
|
<member><literal>day</literal></member>
|
|
<member><literal>week</literal></member>
|
|
<member><literal>month</literal></member>
|
|
<member><literal>quarter</literal></member>
|
|
<member><literal>year</literal></member>
|
|
<member><literal>decade</literal></member>
|
|
<member><literal>century</literal></member>
|
|
<member><literal>millennium</literal></member>
|
|
</simplelist>
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<screen>
|
|
SELECT date_trunc('hour', TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 20:00:00</computeroutput>
|
|
|
|
SELECT date_trunc('year', TIMESTAMP '2001-02-16 20:38:40');
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-01-01 00:00:00</computeroutput>
|
|
</screen>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-datetime-zoneconvert">
|
|
<title><literal>AT TIME ZONE</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>time zone</primary>
|
|
<secondary>conversion</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>AT TIME ZONE</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The <literal>AT TIME ZONE</literal> construct allows conversions
|
|
of time stamps to different time zones. <xref
|
|
linkend="functions-datetime-zoneconvert-table"> shows its
|
|
variants.
|
|
</para>
|
|
|
|
<table id="functions-datetime-zoneconvert-table">
|
|
<title><literal>AT TIME ZONE</literal> Variants</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Expression</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><type>timestamp without time zone</type> AT TIME ZONE <replaceable>zone</></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Treat given time stamp <emphasis>without time zone</> as located in the specified time zone</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal><type>timestamp with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
|
|
</entry>
|
|
<entry><type>timestamp without time zone</type></entry>
|
|
<entry>Convert given time stamp <emphasis>with time zone</> to the new time
|
|
zone, with no time zone designation</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<literal><type>time with time zone</type> AT TIME ZONE <replaceable>zone</></literal>
|
|
</entry>
|
|
<entry><type>time with time zone</type></entry>
|
|
<entry>Convert given time <emphasis>with time zone</> to the new time zone</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
In these expressions, the desired time zone <replaceable>zone</> can be
|
|
specified either as a text string (e.g., <literal>'PST'</literal>)
|
|
or as an interval (e.g., <literal>INTERVAL '-08:00'</literal>).
|
|
In the text case, a time zone name can be specified in any of the ways
|
|
described in <xref linkend="datatype-timezones">.
|
|
</para>
|
|
|
|
<para>
|
|
Examples (assuming the local time zone is <literal>PST8PDT</>):
|
|
<screen>
|
|
SELECT TIMESTAMP '2001-02-16 20:38:40' AT TIME ZONE 'MST';
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 19:38:40-08</computeroutput>
|
|
|
|
SELECT TIMESTAMP WITH TIME ZONE '2001-02-16 20:38:40-05' AT TIME ZONE 'MST';
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-02-16 18:38:40</computeroutput>
|
|
</screen>
|
|
The first example takes a time stamp without time zone and interprets it as MST time
|
|
(UTC-7), which is then converted to PST (UTC-8) for display. The second example takes
|
|
a time stamp specified in EST (UTC-5) and converts it to local time in MST (UTC-7).
|
|
</para>
|
|
|
|
<para>
|
|
The function <literal><function>timezone</function>(<replaceable>zone</>,
|
|
<replaceable>timestamp</>)</literal> is equivalent to the SQL-conforming construct
|
|
<literal><replaceable>timestamp</> AT TIME ZONE
|
|
<replaceable>zone</></literal>.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-datetime-current">
|
|
<title>Current Date/Time</title>
|
|
|
|
<indexterm>
|
|
<primary>date</primary>
|
|
<secondary>current</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>time</primary>
|
|
<secondary>current</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> provides a number of functions
|
|
that return values related to the current date and time. These
|
|
SQL-standard functions all return values based on the start time of
|
|
the current transaction:
|
|
<synopsis>
|
|
CURRENT_DATE
|
|
CURRENT_TIME
|
|
CURRENT_TIMESTAMP
|
|
CURRENT_TIME(<replaceable>precision</replaceable>)
|
|
CURRENT_TIMESTAMP(<replaceable>precision</replaceable>)
|
|
LOCALTIME
|
|
LOCALTIMESTAMP
|
|
LOCALTIME(<replaceable>precision</replaceable>)
|
|
LOCALTIMESTAMP(<replaceable>precision</replaceable>)
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
<function>CURRENT_TIME</function> and
|
|
<function>CURRENT_TIMESTAMP</function> deliver values with time zone;
|
|
<function>LOCALTIME</function> and
|
|
<function>LOCALTIMESTAMP</function> deliver values without time zone.
|
|
</para>
|
|
|
|
<para>
|
|
<function>CURRENT_TIME</function>,
|
|
<function>CURRENT_TIMESTAMP</function>,
|
|
<function>LOCALTIME</function>, and
|
|
<function>LOCALTIMESTAMP</function>
|
|
can optionally take
|
|
a precision parameter, which causes the result to be rounded
|
|
to that many fractional digits in the seconds field. Without a precision parameter,
|
|
the result is given to the full available precision.
|
|
</para>
|
|
|
|
<para>
|
|
Some examples:
|
|
<screen>
|
|
SELECT CURRENT_TIME;
|
|
<lineannotation>Result: </lineannotation><computeroutput>14:39:53.662522-05</computeroutput>
|
|
|
|
SELECT CURRENT_DATE;
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23</computeroutput>
|
|
|
|
SELECT CURRENT_TIMESTAMP;
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522-05</computeroutput>
|
|
|
|
SELECT CURRENT_TIMESTAMP(2);
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.66-05</computeroutput>
|
|
|
|
SELECT LOCALTIMESTAMP;
|
|
<lineannotation>Result: </lineannotation><computeroutput>2001-12-23 14:39:53.662522</computeroutput>
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
Since these functions return
|
|
the start time of the current transaction, their values do not
|
|
change during the transaction. This is considered a feature:
|
|
the intent is to allow a single transaction to have a consistent
|
|
notion of the <quote>current</quote> time, so that multiple
|
|
modifications within the same transaction bear the same
|
|
time stamp.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Other database systems might advance these values more
|
|
frequently.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
<productname>PostgreSQL</productname> also provides functions that
|
|
return the start time of the current statement, as well as the actual
|
|
current time at the instant the function is called. The complete list
|
|
of non-SQL-standard time functions is:
|
|
<synopsis>
|
|
transaction_timestamp()
|
|
statement_timestamp()
|
|
clock_timestamp()
|
|
timeofday()
|
|
now()
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
<function>transaction_timestamp()</> is equivalent to
|
|
<function>CURRENT_TIMESTAMP</function>, but is named to clearly reflect
|
|
what it returns.
|
|
<function>statement_timestamp()</> returns the start time of the current
|
|
statement (more specifically, the time of receipt of the latest command
|
|
message from the client).
|
|
<function>statement_timestamp()</> and <function>transaction_timestamp()</>
|
|
return the same value during the first command of a transaction, but might
|
|
differ during subsequent commands.
|
|
<function>clock_timestamp()</> returns the actual current time, and
|
|
therefore its value changes even within a single SQL command.
|
|
<function>timeofday()</> is a historical
|
|
<productname>PostgreSQL</productname> function. Like
|
|
<function>clock_timestamp()</>, it returns the actual current time,
|
|
but as a formatted <type>text</> string rather than a <type>timestamp
|
|
with time zone</> value.
|
|
<function>now()</> is a traditional <productname>PostgreSQL</productname>
|
|
equivalent to <function>transaction_timestamp()</function>.
|
|
</para>
|
|
|
|
<para>
|
|
All the date/time data types also accept the special literal value
|
|
<literal>now</literal> to specify the current date and time (again,
|
|
interpreted as the transaction start time). Thus,
|
|
the following three all return the same result:
|
|
<programlisting>
|
|
SELECT CURRENT_TIMESTAMP;
|
|
SELECT now();
|
|
SELECT TIMESTAMP 'now'; -- incorrect for use with DEFAULT
|
|
</programlisting>
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
You do not want to use the third form when specifying a <literal>DEFAULT</>
|
|
clause while creating a table. The system will convert <literal>now</literal>
|
|
to a <type>timestamp</type> as soon as the constant is parsed, so that when
|
|
the default value is needed,
|
|
the time of the table creation would be used! The first two
|
|
forms will not be evaluated until the default value is used,
|
|
because they are function calls. Thus they will give the desired
|
|
behavior of defaulting to the time of row insertion.
|
|
</para>
|
|
</tip>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-datetime-delay">
|
|
<title>Delaying Execution</title>
|
|
|
|
<indexterm>
|
|
<primary>pg_sleep</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>sleep</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>delay</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The following function is available to delay execution of the server
|
|
process:
|
|
<synopsis>
|
|
pg_sleep(<replaceable>seconds</replaceable>)
|
|
</synopsis>
|
|
|
|
<function>pg_sleep</function> makes the current session's process
|
|
sleep until <replaceable>seconds</replaceable> seconds have
|
|
elapsed. <replaceable>seconds</replaceable> is a value of type
|
|
<type>double precision</>, so fractional-second delays can be specified.
|
|
For example:
|
|
|
|
<programlisting>
|
|
SELECT pg_sleep(1.5);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The effective resolution of the sleep interval is platform-specific;
|
|
0.01 seconds is a common value. The sleep delay will be at least as long
|
|
as specified. It might be longer depending on factors such as server load.
|
|
</para>
|
|
</note>
|
|
|
|
<warning>
|
|
<para>
|
|
Make sure that your session does not hold more locks than necessary
|
|
when calling <function>pg_sleep</function>. Otherwise other sessions
|
|
might have to wait for your sleeping process, slowing down the entire
|
|
system.
|
|
</para>
|
|
</warning>
|
|
</sect2>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-enum">
|
|
<title>Enum Support Functions</title>
|
|
|
|
<para>
|
|
For enum types (described in <xref linkend="datatype-enum">),
|
|
there are several functions that allow cleaner programming without
|
|
hard-coding particular values of an enum type.
|
|
These are listed in <xref linkend="functions-enum-table">. The examples
|
|
assume an enum type created as:
|
|
|
|
<programlisting>
|
|
CREATE TYPE rainbow AS ENUM ('red', 'orange', 'yellow', 'green', 'blue', 'purple');
|
|
</programlisting>
|
|
|
|
</para>
|
|
|
|
<table id="functions-enum-table">
|
|
<title>Enum Support Functions</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Example Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>enum_first</primary>
|
|
</indexterm>
|
|
<literal>enum_first(anyenum)</literal>
|
|
</entry>
|
|
<entry>Returns the first value of the input enum type</entry>
|
|
<entry><literal>enum_first(null::rainbow)</literal></entry>
|
|
<entry><literal>red</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>enum_last</primary>
|
|
</indexterm>
|
|
<literal>enum_last(anyenum)</literal>
|
|
</entry>
|
|
<entry>Returns the last value of the input enum type</entry>
|
|
<entry><literal>enum_last(null::rainbow)</literal></entry>
|
|
<entry><literal>purple</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>enum_range</primary>
|
|
</indexterm>
|
|
<literal>enum_range(anyenum)</literal>
|
|
</entry>
|
|
<entry>Returns all values of the input enum type in an ordered array</entry>
|
|
<entry><literal>enum_range(null::rainbow)</literal></entry>
|
|
<entry><literal>{red,orange,yellow,green,blue,purple}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry morerows="2"><literal>enum_range(anyenum, anyenum)</literal></entry>
|
|
<entry morerows="2">
|
|
Returns the range between the two given enum values, as an ordered
|
|
array. The values must be from the same enum type. If the first
|
|
parameter is null, the result will start with the first value of
|
|
the enum type.
|
|
If the second parameter is null, the result will end with the last
|
|
value of the enum type.
|
|
</entry>
|
|
<entry><literal>enum_range('orange'::rainbow, 'green'::rainbow)</literal></entry>
|
|
<entry><literal>{orange,yellow,green}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>enum_range(NULL, 'green'::rainbow)</literal></entry>
|
|
<entry><literal>{red,orange,yellow,green}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal>enum_range('orange'::rainbow, NULL)</literal></entry>
|
|
<entry><literal>{orange,yellow,green,blue,purple}</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Notice that except for the two-argument form of <function>enum_range</>,
|
|
these functions disregard the specific value passed to them; they care
|
|
only about its declared data type. Either null or a specific value of
|
|
the type can be passed, with the same result. It is more common to
|
|
apply these functions to a table column or function argument than to
|
|
a hardwired type name as suggested by the examples.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="functions-geometry">
|
|
<title>Geometric Functions and Operators</title>
|
|
|
|
<para>
|
|
The geometric types <type>point</type>, <type>box</type>,
|
|
<type>lseg</type>, <type>line</type>, <type>path</type>,
|
|
<type>polygon</type>, and <type>circle</type> have a large set of
|
|
native support functions and operators, shown in <xref
|
|
linkend="functions-geometry-op-table">, <xref
|
|
linkend="functions-geometry-func-table">, and <xref
|
|
linkend="functions-geometry-conv-table">.
|
|
</para>
|
|
|
|
<caution>
|
|
<para>
|
|
Note that the <quote>same as</> operator, <literal>~=</>, represents
|
|
the usual notion of equality for the <type>point</type>,
|
|
<type>box</type>, <type>polygon</type>, and <type>circle</type> types.
|
|
Some of these types also have an <literal>=</> operator, but
|
|
<literal>=</> compares
|
|
for equal <emphasis>areas</> only. The other scalar comparison operators
|
|
(<literal><=</> and so on) likewise compare areas for these types.
|
|
</para>
|
|
</caution>
|
|
|
|
<table id="functions-geometry-op-table">
|
|
<title>Geometric Operators</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry>Translation</entry>
|
|
<entry><literal>box '((0,0),(1,1))' + point '(2.0,0)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry>Translation</entry>
|
|
<entry><literal>box '((0,0),(1,1))' - point '(2.0,0)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>*</literal> </entry>
|
|
<entry>Scaling/rotation</entry>
|
|
<entry><literal>box '((0,0),(1,1))' * point '(2.0,0)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>/</literal> </entry>
|
|
<entry>Scaling/rotation</entry>
|
|
<entry><literal>box '((0,0),(2,2))' / point '(2.0,0)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>#</literal> </entry>
|
|
<entry>Point or box of intersection</entry>
|
|
<entry><literal>'((1,-1),(-1,1))' # '((1,1),(-1,-1))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>#</literal> </entry>
|
|
<entry>Number of points in path or polygon</entry>
|
|
<entry><literal># '((1,0),(0,1),(-1,0))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>@-@</literal> </entry>
|
|
<entry>Length or circumference</entry>
|
|
<entry><literal>@-@ path '((0,0),(1,0))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>@@</literal> </entry>
|
|
<entry>Center</entry>
|
|
<entry><literal>@@ circle '((0,0),10)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>##</literal> </entry>
|
|
<entry>Closest point to first operand on second operand</entry>
|
|
<entry><literal>point '(0,0)' ## lseg '((2,0),(0,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><-></literal> </entry>
|
|
<entry>Distance between</entry>
|
|
<entry><literal>circle '((0,0),1)' <-> circle '((5,0),1)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>&&</literal> </entry>
|
|
<entry>Overlaps? (One point in common makes this true.)</entry>
|
|
<entry><literal>box '((0,0),(1,1))' && box '((0,0),(2,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><<</literal> </entry>
|
|
<entry>Is strictly left of?</entry>
|
|
<entry><literal>circle '((0,0),1)' << circle '((5,0),1)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>>></literal> </entry>
|
|
<entry>Is strictly right of?</entry>
|
|
<entry><literal>circle '((5,0),1)' >> circle '((0,0),1)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>&<</literal> </entry>
|
|
<entry>Does not extend to the right of?</entry>
|
|
<entry><literal>box '((0,0),(1,1))' &< box '((0,0),(2,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>&></literal> </entry>
|
|
<entry>Does not extend to the left of?</entry>
|
|
<entry><literal>box '((0,0),(3,3))' &> box '((0,0),(2,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><<|</literal> </entry>
|
|
<entry>Is strictly below?</entry>
|
|
<entry><literal>box '((0,0),(3,3))' <<| box '((3,4),(5,5))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>|>></literal> </entry>
|
|
<entry>Is strictly above?</entry>
|
|
<entry><literal>box '((3,4),(5,5))' |>> box '((0,0),(3,3))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>&<|</literal> </entry>
|
|
<entry>Does not extend above?</entry>
|
|
<entry><literal>box '((0,0),(1,1))' &<| box '((0,0),(2,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>|&></literal> </entry>
|
|
<entry>Does not extend below?</entry>
|
|
<entry><literal>box '((0,0),(3,3))' |&> box '((0,0),(2,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><^</literal> </entry>
|
|
<entry>Is below (allows touching)?</entry>
|
|
<entry><literal>circle '((0,0),1)' <^ circle '((0,5),1)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>>^</literal> </entry>
|
|
<entry>Is above (allows touching)?</entry>
|
|
<entry><literal>circle '((0,5),1)' >^ circle '((0,0),1)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>?#</literal> </entry>
|
|
<entry>Intersects?</entry>
|
|
<entry><literal>lseg '((-1,0),(1,0))' ?# box '((-2,-2),(2,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>?-</literal> </entry>
|
|
<entry>Is horizontal?</entry>
|
|
<entry><literal>?- lseg '((-1,0),(1,0))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>?-</literal> </entry>
|
|
<entry>Are horizontally aligned?</entry>
|
|
<entry><literal>point '(1,0)' ?- point '(0,0)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>?|</literal> </entry>
|
|
<entry>Is vertical?</entry>
|
|
<entry><literal>?| lseg '((-1,0),(1,0))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>?|</literal> </entry>
|
|
<entry>Are vertically aligned?</entry>
|
|
<entry><literal>point '(0,1)' ?| point '(0,0)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>?-|</literal> </entry>
|
|
<entry>Is perpendicular?</entry>
|
|
<entry><literal>lseg '((0,0),(0,1))' ?-| lseg '((0,0),(1,0))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>?||</literal> </entry>
|
|
<entry>Are parallel?</entry>
|
|
<entry><literal>lseg '((-1,0),(1,0))' ?|| lseg '((-1,2),(1,2))'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>@></literal> </entry>
|
|
<entry>Contains?</entry>
|
|
<entry><literal>circle '((0,0),2)' @> point '(1,1)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><@</literal> </entry>
|
|
<entry>Contained in or on?</entry>
|
|
<entry><literal>point '(1,1)' <@ circle '((0,0),2)'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>~=</literal> </entry>
|
|
<entry>Same as?</entry>
|
|
<entry><literal>polygon '((0,0),(1,1))' ~= polygon '((1,1),(0,0))'</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
Before <productname>PostgreSQL</productname> 8.2, the containment
|
|
operators <literal>@></> and <literal><@</> were respectively
|
|
called <literal>~</> and <literal>@</>. These names are still
|
|
available, but are deprecated and will eventually be removed.
|
|
</para>
|
|
</note>
|
|
|
|
<indexterm>
|
|
<primary>area</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>center</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>diameter</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>height</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>isclosed</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>isopen</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>length</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>npoints</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pclose</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>popen</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>radius</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>width</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-geometry-func-table">
|
|
<title>Geometric Functions</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>area(<replaceable>object</>)</function></literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>area</entry>
|
|
<entry><literal>area(box '((0,0),(1,1))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>center(<replaceable>object</>)</function></literal></entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>center</entry>
|
|
<entry><literal>center(box '((0,0),(1,2))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>diameter(<type>circle</>)</function></literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>diameter of circle</entry>
|
|
<entry><literal>diameter(circle '((0,0),2.0)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>height(<type>box</>)</function></literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>vertical size of box</entry>
|
|
<entry><literal>height(box '((0,0),(1,1))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>isclosed(<type>path</>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>a closed path?</entry>
|
|
<entry><literal>isclosed(path '((0,0),(1,1),(2,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>isopen(<type>path</>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>an open path?</entry>
|
|
<entry><literal>isopen(path '[(0,0),(1,1),(2,0)]')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>length(<replaceable>object</>)</function></literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>length</entry>
|
|
<entry><literal>length(path '((-1,0),(1,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>npoints(<type>path</>)</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>number of points</entry>
|
|
<entry><literal>npoints(path '[(0,0),(1,1),(2,0)]')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>npoints(<type>polygon</>)</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>number of points</entry>
|
|
<entry><literal>npoints(polygon '((1,1),(0,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pclose(<type>path</>)</function></literal></entry>
|
|
<entry><type>path</type></entry>
|
|
<entry>convert path to closed</entry>
|
|
<entry><literal>pclose(path '[(0,0),(1,1),(2,0)]')</literal></entry>
|
|
</row>
|
|
<![IGNORE[
|
|
<!-- Not defined by this name. Implements the intersection operator '#' -->
|
|
<row>
|
|
<entry><literal><function>point(<type>lseg</>, <type>lseg</>)</function></literal></entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>intersection</entry>
|
|
<entry><literal>point(lseg '((-1,0),(1,0))',lseg '((-2,-2),(2,2))')</literal></entry>
|
|
</row>
|
|
]]>
|
|
<row>
|
|
<entry><literal><function>popen(<type>path</>)</function></literal></entry>
|
|
<entry><type>path</type></entry>
|
|
<entry>convert path to open</entry>
|
|
<entry><literal>popen(path '((0,0),(1,1),(2,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>radius(<type>circle</type>)</function></literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>radius of circle</entry>
|
|
<entry><literal>radius(circle '((0,0),2.0)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>width(<type>box</>)</function></literal></entry>
|
|
<entry><type>double precision</type></entry>
|
|
<entry>horizontal size of box</entry>
|
|
<entry><literal>width(box '((0,0),(1,1))')</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<table id="functions-geometry-conv-table">
|
|
<title>Geometric Type Conversion Functions</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>box</primary>
|
|
</indexterm>
|
|
<literal><function>box(<type>circle</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>box</type></entry>
|
|
<entry>circle to box</entry>
|
|
<entry><literal>box(circle '((0,0),2.0)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>box(<type>point</type>, <type>point</type>)</function></literal></entry>
|
|
<entry><type>box</type></entry>
|
|
<entry>points to box</entry>
|
|
<entry><literal>box(point '(0,0)', point '(1,1)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>box(<type>polygon</type>)</function></literal></entry>
|
|
<entry><type>box</type></entry>
|
|
<entry>polygon to box</entry>
|
|
<entry><literal>box(polygon '((0,0),(1,1),(2,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>circle</primary>
|
|
</indexterm>
|
|
<literal><function>circle(<type>box</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>circle</type></entry>
|
|
<entry>box to circle</entry>
|
|
<entry><literal>circle(box '((0,0),(1,1))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>circle(<type>point</type>, <type>double precision</type>)</function></literal></entry>
|
|
<entry><type>circle</type></entry>
|
|
<entry>center and radius to circle</entry>
|
|
<entry><literal>circle(point '(0,0)', 2.0)</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>circle(<type>polygon</type>)</function></literal></entry>
|
|
<entry><type>circle</type></entry>
|
|
<entry>polygon to circle</entry>
|
|
<entry><literal>circle(polygon '((0,0),(1,1),(2,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>lseg</primary>
|
|
</indexterm>
|
|
<literal><function>lseg(<type>box</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>lseg</type></entry>
|
|
<entry>box diagonal to line segment</entry>
|
|
<entry><literal>lseg(box '((-1,0),(1,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>lseg(<type>point</type>, <type>point</type>)</function></literal></entry>
|
|
<entry><type>lseg</type></entry>
|
|
<entry>points to line segment</entry>
|
|
<entry><literal>lseg(point '(-1,0)', point '(1,0)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>path</primary>
|
|
</indexterm>
|
|
<literal><function>path(<type>polygon</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>polygon to path</entry>
|
|
<entry><literal>path(polygon '((0,0),(1,1),(2,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>point</primary>
|
|
</indexterm>
|
|
<literal><function>point</function>(<type>double
|
|
precision</type>, <type>double precision</type>)</literal>
|
|
</entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>construct point</entry>
|
|
<entry><literal>point(23.4, -44.5)</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>point(<type>box</type>)</function></literal></entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>center of box</entry>
|
|
<entry><literal>point(box '((-1,0),(1,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>point(<type>circle</type>)</function></literal></entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>center of circle</entry>
|
|
<entry><literal>point(circle '((0,0),2.0)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>point(<type>lseg</type>)</function></literal></entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>center of line segment</entry>
|
|
<entry><literal>point(lseg '((-1,0),(1,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>point(<type>polygon</type>)</function></literal></entry>
|
|
<entry><type>point</type></entry>
|
|
<entry>center of polygon</entry>
|
|
<entry><literal>point(polygon '((0,0),(1,1),(2,0))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>polygon</primary>
|
|
</indexterm>
|
|
<literal><function>polygon(<type>box</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>polygon</type></entry>
|
|
<entry>box to 4-point polygon</entry>
|
|
<entry><literal>polygon(box '((0,0),(1,1))')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>polygon(<type>circle</type>)</function></literal></entry>
|
|
<entry><type>polygon</type></entry>
|
|
<entry>circle to 12-point polygon</entry>
|
|
<entry><literal>polygon(circle '((0,0),2.0)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>polygon(<replaceable class="parameter">npts</replaceable>, <type>circle</type>)</function></literal></entry>
|
|
<entry><type>polygon</type></entry>
|
|
<entry>circle to <replaceable class="parameter">npts</replaceable>-point polygon</entry>
|
|
<entry><literal>polygon(12, circle '((0,0),2.0)')</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>polygon(<type>path</type>)</function></literal></entry>
|
|
<entry><type>polygon</type></entry>
|
|
<entry>path to polygon</entry>
|
|
<entry><literal>polygon(path '((0,0),(1,1),(2,0))')</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
It is possible to access the two component numbers of a <type>point</>
|
|
as though the point were an array with indexes 0 and 1. For example, if
|
|
<literal>t.p</> is a <type>point</> column then
|
|
<literal>SELECT p[0] FROM t</> retrieves the X coordinate and
|
|
<literal>UPDATE t SET p[1] = ...</> changes the Y coordinate.
|
|
In the same way, a value of type <type>box</> or <type>lseg</> can be treated
|
|
as an array of two <type>point</> values.
|
|
</para>
|
|
|
|
<para>
|
|
The <function>area</function> function works for the types
|
|
<type>box</type>, <type>circle</type>, and <type>path</type>.
|
|
The <function>area</function> function only works on the
|
|
<type>path</type> data type if the points in the
|
|
<type>path</type> are non-intersecting. For example, the
|
|
<type>path</type>
|
|
<literal>'((0,0),(0,1),(2,1),(2,2),(1,2),(1,0),(0,0))'::PATH</literal>
|
|
will not work; however, the following visually identical
|
|
<type>path</type>
|
|
<literal>'((0,0),(0,1),(1,1),(1,2),(2,2),(2,1),(1,1),(1,0),(0,0))'::PATH</literal>
|
|
will work. If the concept of an intersecting versus
|
|
non-intersecting <type>path</type> is confusing, draw both of the
|
|
above <type>path</type>s side by side on a piece of graph paper.
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-net">
|
|
<title>Network Address Functions and Operators</title>
|
|
|
|
<para>
|
|
<xref linkend="cidr-inet-operators-table"> shows the operators
|
|
available for the <type>cidr</type> and <type>inet</type> types.
|
|
The operators <literal><<</literal>,
|
|
<literal><<=</literal>, <literal>>></literal>, and
|
|
<literal>>>=</literal> test for subnet inclusion. They
|
|
consider only the network parts of the two addresses (ignoring any
|
|
host part) and determine whether one network is identical to
|
|
or a subnet of the other.
|
|
</para>
|
|
|
|
<table id="cidr-inet-operators-table">
|
|
<title><type>cidr</type> and <type>inet</type> Operators</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal><</literal> </entry>
|
|
<entry>is less than</entry>
|
|
<entry><literal>inet '192.168.1.5' < inet '192.168.1.6'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><=</literal> </entry>
|
|
<entry>is less than or equal</entry>
|
|
<entry><literal>inet '192.168.1.5' <= inet '192.168.1.5'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>=</literal> </entry>
|
|
<entry>equals</entry>
|
|
<entry><literal>inet '192.168.1.5' = inet '192.168.1.5'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>>=</literal> </entry>
|
|
<entry>is greater or equal</entry>
|
|
<entry><literal>inet '192.168.1.5' >= inet '192.168.1.5'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>></literal> </entry>
|
|
<entry>is greater than</entry>
|
|
<entry><literal>inet '192.168.1.5' > inet '192.168.1.4'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><></literal> </entry>
|
|
<entry>is not equal</entry>
|
|
<entry><literal>inet '192.168.1.5' <> inet '192.168.1.4'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><<</literal> </entry>
|
|
<entry>is contained within</entry>
|
|
<entry><literal>inet '192.168.1.5' << inet '192.168.1/24'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><<=</literal> </entry>
|
|
<entry>is contained within or equals</entry>
|
|
<entry><literal>inet '192.168.1/24' <<= inet '192.168.1/24'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>>></literal> </entry>
|
|
<entry>contains</entry>
|
|
<entry><literal>inet '192.168.1/24' >> inet '192.168.1.5'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>>>=</literal> </entry>
|
|
<entry>contains or equals</entry>
|
|
<entry><literal>inet '192.168.1/24' >>= inet '192.168.1/24'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>~</literal> </entry>
|
|
<entry>bitwise NOT</entry>
|
|
<entry><literal>~ inet '192.168.1.6'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>&</literal> </entry>
|
|
<entry>bitwise AND</entry>
|
|
<entry><literal>inet '192.168.1.6' & inet '0.0.0.255'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>|</literal> </entry>
|
|
<entry>bitwise OR</entry>
|
|
<entry><literal>inet '192.168.1.6' | inet '0.0.0.255'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>+</literal> </entry>
|
|
<entry>addition</entry>
|
|
<entry><literal>inet '192.168.1.6' + 25</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry>subtraction</entry>
|
|
<entry><literal>inet '192.168.1.43' - 36</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>-</literal> </entry>
|
|
<entry>subtraction</entry>
|
|
<entry><literal>inet '192.168.1.43' - inet '192.168.1.19'</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<xref linkend="cidr-inet-functions-table"> shows the functions
|
|
available for use with the <type>cidr</type> and <type>inet</type>
|
|
types. The <function>abbrev</function>, <function>host</function>,
|
|
and <function>text</function>
|
|
functions are primarily intended to offer alternative display
|
|
formats.
|
|
</para>
|
|
|
|
<table id="cidr-inet-functions-table">
|
|
<title><type>cidr</type> and <type>inet</type> Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>abbrev</primary>
|
|
</indexterm>
|
|
<literal><function>abbrev(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>abbreviated display format as text</entry>
|
|
<entry><literal>abbrev(inet '10.1.0.0/16')</literal></entry>
|
|
<entry><literal>10.1.0.0/16</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>abbrev(<type>cidr</type>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>abbreviated display format as text</entry>
|
|
<entry><literal>abbrev(cidr '10.1.0.0/16')</literal></entry>
|
|
<entry><literal>10.1/16</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>broadcast</primary>
|
|
</indexterm>
|
|
<literal><function>broadcast(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>inet</type></entry>
|
|
<entry>broadcast address for network</entry>
|
|
<entry><literal>broadcast('192.168.1.5/24')</literal></entry>
|
|
<entry><literal>192.168.1.255/24</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>family</primary>
|
|
</indexterm>
|
|
<literal><function>family(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>extract family of address; <literal>4</literal> for IPv4,
|
|
<literal>6</literal> for IPv6</entry>
|
|
<entry><literal>family('::1')</literal></entry>
|
|
<entry><literal>6</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>host</primary>
|
|
</indexterm>
|
|
<literal><function>host(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>extract IP address as text</entry>
|
|
<entry><literal>host('192.168.1.5/24')</literal></entry>
|
|
<entry><literal>192.168.1.5</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>hostmask</primary>
|
|
</indexterm>
|
|
<literal><function>hostmask(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>inet</type></entry>
|
|
<entry>construct host mask for network</entry>
|
|
<entry><literal>hostmask('192.168.23.20/30')</literal></entry>
|
|
<entry><literal>0.0.0.3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>masklen</primary>
|
|
</indexterm>
|
|
<literal><function>masklen(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>extract netmask length</entry>
|
|
<entry><literal>masklen('192.168.1.5/24')</literal></entry>
|
|
<entry><literal>24</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>netmask</primary>
|
|
</indexterm>
|
|
<literal><function>netmask(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>inet</type></entry>
|
|
<entry>construct netmask for network</entry>
|
|
<entry><literal>netmask('192.168.1.5/24')</literal></entry>
|
|
<entry><literal>255.255.255.0</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>network</primary>
|
|
</indexterm>
|
|
<literal><function>network(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>cidr</type></entry>
|
|
<entry>extract network part of address</entry>
|
|
<entry><literal>network('192.168.1.5/24')</literal></entry>
|
|
<entry><literal>192.168.1.0/24</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>set_masklen</primary>
|
|
</indexterm>
|
|
<literal><function>set_masklen(<type>inet</type>, <type>int</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>inet</type></entry>
|
|
<entry>set netmask length for <type>inet</type> value</entry>
|
|
<entry><literal>set_masklen('192.168.1.5/24', 16)</literal></entry>
|
|
<entry><literal>192.168.1.5/16</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>set_masklen(<type>cidr</type>, <type>int</type>)</function></literal></entry>
|
|
<entry><type>cidr</type></entry>
|
|
<entry>set netmask length for <type>cidr</type> value</entry>
|
|
<entry><literal>set_masklen('192.168.1.0/24'::cidr, 16)</literal></entry>
|
|
<entry><literal>192.168.0.0/16</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>text</primary>
|
|
</indexterm>
|
|
<literal><function>text(<type>inet</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>extract IP address and netmask length as text</entry>
|
|
<entry><literal>text(inet '192.168.1.5')</literal></entry>
|
|
<entry><literal>192.168.1.5/32</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Any <type>cidr</> value can be cast to <type>inet</> implicitly
|
|
or explicitly; therefore, the functions shown above as operating on
|
|
<type>inet</> also work on <type>cidr</> values. (Where there are
|
|
separate functions for <type>inet</> and <type>cidr</>, it is because
|
|
the behavior should be different for the two cases.)
|
|
Also, it is permitted to cast an <type>inet</> value to <type>cidr</>.
|
|
When this is done, any bits to the right of the netmask are silently zeroed
|
|
to create a valid <type>cidr</> value.
|
|
In addition,
|
|
you can cast a text value to <type>inet</> or <type>cidr</>
|
|
using normal casting syntax: for example,
|
|
<literal>inet(<replaceable>expression</>)</literal> or
|
|
<literal><replaceable>colname</>::cidr</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="macaddr-functions-table"> shows the functions
|
|
available for use with the <type>macaddr</type> type. The function
|
|
<literal><function>trunc(<type>macaddr</type>)</function></literal> returns a MAC
|
|
address with the last 3 bytes set to zero. This can be used to
|
|
associate the remaining prefix with a manufacturer.
|
|
</para>
|
|
|
|
<table id="macaddr-functions-table">
|
|
<title><type>macaddr</type> Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>trunc</primary>
|
|
</indexterm>
|
|
<literal><function>trunc(<type>macaddr</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>macaddr</type></entry>
|
|
<entry>set last 3 bytes to zero</entry>
|
|
<entry><literal>trunc(macaddr '12:34:56:78:90:ab')</literal></entry>
|
|
<entry><literal>12:34:56:00:00:00</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The <type>macaddr</type> type also supports the standard relational
|
|
operators (<literal>></literal>, <literal><=</literal>, etc.) for
|
|
lexicographical ordering.
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-textsearch">
|
|
<title>Text Search Functions and Operators</title>
|
|
|
|
<indexterm zone="datatype-textsearch">
|
|
<primary>full text search</primary>
|
|
<secondary>functions and operators</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm zone="datatype-textsearch">
|
|
<primary>text search</primary>
|
|
<secondary>functions and operators</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<xref linkend="textsearch-operators-table">,
|
|
<xref linkend="textsearch-functions-table"> and
|
|
<xref linkend="textsearch-functions-debug-table">
|
|
summarize the functions and operators that are provided
|
|
for full text searching. See <xref linkend="textsearch"> for a detailed
|
|
explanation of <productname>PostgreSQL</productname>'s text search
|
|
facility.
|
|
</para>
|
|
|
|
<table id="textsearch-operators-table">
|
|
<title>Text Search Operators</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>@@</literal> </entry>
|
|
<entry><type>tsvector</> matches <type>tsquery</> ?</entry>
|
|
<entry><literal>to_tsvector('fat cats ate rats') @@ to_tsquery('cat & rat')</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>@@@</literal> </entry>
|
|
<entry>deprecated synonym for <literal>@@</></entry>
|
|
<entry><literal>to_tsvector('fat cats ate rats') @@@ to_tsquery('cat & rat')</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>||</literal> </entry>
|
|
<entry>concatenate <type>tsvector</>s</entry>
|
|
<entry><literal>'a:1 b:2'::tsvector || 'c:1 d:2 b:3'::tsvector</literal></entry>
|
|
<entry><literal>'a':1 'b':2,5 'c':3 'd':4</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>&&</literal> </entry>
|
|
<entry>AND <type>tsquery</>s together</entry>
|
|
<entry><literal>'fat | rat'::tsquery && 'cat'::tsquery</literal></entry>
|
|
<entry><literal>( 'fat' | 'rat' ) & 'cat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>||</literal> </entry>
|
|
<entry>OR <type>tsquery</>s together</entry>
|
|
<entry><literal>'fat | rat'::tsquery || 'cat'::tsquery</literal></entry>
|
|
<entry><literal>( 'fat' | 'rat' ) | 'cat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>!!</literal> </entry>
|
|
<entry>negate a <type>tsquery</></entry>
|
|
<entry><literal>!! 'cat'::tsquery</literal></entry>
|
|
<entry><literal>!'cat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal>@></literal> </entry>
|
|
<entry><type>tsquery</> contains another ?</entry>
|
|
<entry><literal>'cat'::tsquery @> 'cat & rat'::tsquery</literal></entry>
|
|
<entry><literal>f</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry> <literal><@</literal> </entry>
|
|
<entry><type>tsquery</> is contained in ?</entry>
|
|
<entry><literal>'cat'::tsquery <@ 'cat & rat'::tsquery</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
The <type>tsquery</> containment operators consider only the lexemes
|
|
listed in the two queries, ignoring the combining operators.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
In addition to the operators shown in the table, the ordinary B-tree
|
|
comparison operators (<literal>=</>, <literal><</>, etc) are defined
|
|
for types <type>tsvector</> and <type>tsquery</>. These are not very
|
|
useful for text searching but allow, for example, unique indexes to be
|
|
built on columns of these types.
|
|
</para>
|
|
|
|
<table id="textsearch-functions-table">
|
|
<title>Text Search Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>get_current_ts_config</primary>
|
|
</indexterm>
|
|
<literal><function>get_current_ts_config()</function></literal>
|
|
</entry>
|
|
<entry><type>regconfig</type></entry>
|
|
<entry>get default text search configuration</entry>
|
|
<entry><literal>get_current_ts_config()</literal></entry>
|
|
<entry><literal>english</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>length</primary>
|
|
</indexterm>
|
|
<literal><function>length(<type>tsvector</>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>number of lexemes in <type>tsvector</></entry>
|
|
<entry><literal>length('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>numnode</primary>
|
|
</indexterm>
|
|
<literal><function>numnode(<type>tsquery</>)</function></literal>
|
|
</entry>
|
|
<entry><type>integer</type></entry>
|
|
<entry>number of lexemes plus operators in <type>tsquery</></entry>
|
|
<entry><literal> numnode('(fat & rat) | cat'::tsquery)</literal></entry>
|
|
<entry><literal>5</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>plainto_tsquery</primary>
|
|
</indexterm>
|
|
<literal><function>plainto_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>produce <type>tsquery</> ignoring punctuation</entry>
|
|
<entry><literal>plainto_tsquery('english', 'The Fat Rats')</literal></entry>
|
|
<entry><literal>'fat' & 'rat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>querytree</primary>
|
|
</indexterm>
|
|
<literal><function>querytree(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get indexable part of a <type>tsquery</></entry>
|
|
<entry><literal>querytree('foo & ! bar'::tsquery)</literal></entry>
|
|
<entry><literal>'foo'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>setweight</primary>
|
|
</indexterm>
|
|
<literal><function>setweight(<type>tsvector</>, <type>"char"</>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>assign weight to each element of <type>tsvector</></entry>
|
|
<entry><literal>setweight('fat:2,4 cat:3 rat:5B'::tsvector, 'A')</literal></entry>
|
|
<entry><literal>'cat':3A 'fat':2A,4A 'rat':5A</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>strip</primary>
|
|
</indexterm>
|
|
<literal><function>strip(<type>tsvector</>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>remove positions and weights from <type>tsvector</></entry>
|
|
<entry><literal>strip('fat:2,4 cat:3 rat:5A'::tsvector)</literal></entry>
|
|
<entry><literal>'cat' 'fat' 'rat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_tsquery</primary>
|
|
</indexterm>
|
|
<literal><function>to_tsquery(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">query</> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>normalize words and convert to <type>tsquery</></entry>
|
|
<entry><literal>to_tsquery('english', 'The & Fat & Rats')</literal></entry>
|
|
<entry><literal>'fat' & 'rat'</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>to_tsvector</primary>
|
|
</indexterm>
|
|
<literal><function>to_tsvector(<optional> <replaceable class="PARAMETER">config</> <type>regconfig</> , </optional> <replaceable class="PARAMETER">document</> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsvector</type></entry>
|
|
<entry>reduce document text to <type>tsvector</></entry>
|
|
<entry><literal>to_tsvector('english', 'The Fat Rats')</literal></entry>
|
|
<entry><literal>'fat':2 'rat':3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_headline</primary>
|
|
</indexterm>
|
|
<literal><function>ts_headline(<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>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>display a query match</entry>
|
|
<entry><literal>ts_headline('x y z', 'z'::tsquery)</literal></entry>
|
|
<entry><literal>x y <b>z</b></literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_rank</primary>
|
|
</indexterm>
|
|
<literal><function>ts_rank(<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>)</function></literal>
|
|
</entry>
|
|
<entry><type>float4</type></entry>
|
|
<entry>rank document for query</entry>
|
|
<entry><literal>ts_rank(textsearch, query)</literal></entry>
|
|
<entry><literal>0.818</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_rank_cd</primary>
|
|
</indexterm>
|
|
<literal><function>ts_rank_cd(<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>)</function></literal>
|
|
</entry>
|
|
<entry><type>float4</type></entry>
|
|
<entry>rank document for query using cover density</entry>
|
|
<entry><literal>ts_rank_cd('{0.1, 0.2, 0.4, 1.0}', textsearch, query)</literal></entry>
|
|
<entry><literal>2.01317</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_rewrite</primary>
|
|
</indexterm>
|
|
<literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">target</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">substitute</replaceable> <type>tsquery</>)</function></literal>
|
|
</entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>replace target with substitute within query</entry>
|
|
<entry><literal>ts_rewrite('a & b'::tsquery, 'a'::tsquery, 'foo|bar'::tsquery)</literal></entry>
|
|
<entry><literal>'b' & ( 'foo' | 'bar' )</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>ts_rewrite(<replaceable class="PARAMETER">query</replaceable> <type>tsquery</>, <replaceable class="PARAMETER">select</replaceable> <type>text</>)</function></literal></entry>
|
|
<entry><type>tsquery</type></entry>
|
|
<entry>replace using targets and substitutes from a <command>SELECT</> command</entry>
|
|
<entry><literal>SELECT ts_rewrite('a & b'::tsquery, 'SELECT t,s FROM aliases')</literal></entry>
|
|
<entry><literal>'b' & ( 'foo' | 'bar' )</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>tsvector_update_trigger</primary>
|
|
</indexterm>
|
|
<literal><function>tsvector_update_trigger()</function></literal>
|
|
</entry>
|
|
<entry><type>trigger</type></entry>
|
|
<entry>trigger function for automatic <type>tsvector</> column update</entry>
|
|
<entry><literal>CREATE TRIGGER ... tsvector_update_trigger(tsvcol, 'pg_catalog.swedish', title, body)</literal></entry>
|
|
<entry><literal></literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>tsvector_update_trigger_column</primary>
|
|
</indexterm>
|
|
<literal><function>tsvector_update_trigger_column()</function></literal>
|
|
</entry>
|
|
<entry><type>trigger</type></entry>
|
|
<entry>trigger function for automatic <type>tsvector</> column update</entry>
|
|
<entry><literal>CREATE TRIGGER ... tsvector_update_trigger_column(tsvcol, configcol, title, body)</literal></entry>
|
|
<entry><literal></literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
All the text search functions that accept an optional <type>regconfig</>
|
|
argument will use the configuration specified by
|
|
<xref linkend="guc-default-text-search-config">
|
|
when that argument is omitted.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The functions in
|
|
<xref linkend="textsearch-functions-debug-table">
|
|
are listed separately because they are not usually used in everyday text
|
|
searching operations. They are helpful for development and debugging
|
|
of new text search configurations.
|
|
</para>
|
|
|
|
<table id="textsearch-functions-debug-table">
|
|
<title>Text Search Debugging Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_debug</primary>
|
|
</indexterm>
|
|
<literal><function>ts_debug(<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[]</>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>test a configuration</entry>
|
|
<entry><literal>ts_debug('english', 'The Brightest supernovaes')</literal></entry>
|
|
<entry><literal>(asciiword,"Word, all ASCII",The,{english_stem},english_stem,{}) ...</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_lexize</primary>
|
|
</indexterm>
|
|
<literal><function>ts_lexize(<replaceable class="PARAMETER">dict</replaceable> <type>regdictionary</>, <replaceable class="PARAMETER">token</replaceable> <type>text</>)</function></literal>
|
|
</entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>test a dictionary</entry>
|
|
<entry><literal>ts_lexize('english_stem', 'stars')</literal></entry>
|
|
<entry><literal>{star}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_parse</primary>
|
|
</indexterm>
|
|
<literal><function>ts_parse(<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</>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>test a parser</entry>
|
|
<entry><literal>ts_parse('default', 'foo - bar')</literal></entry>
|
|
<entry><literal>(1,foo) ...</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>ts_parse(<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</>)</function></literal></entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>test a parser</entry>
|
|
<entry><literal>ts_parse(3722, 'foo - bar')</literal></entry>
|
|
<entry><literal>(1,foo) ...</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_token_type</primary>
|
|
</indexterm>
|
|
<literal><function>ts_token_type(<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</>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>get token types defined by parser</entry>
|
|
<entry><literal>ts_token_type('default')</literal></entry>
|
|
<entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>ts_token_type(<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</>)</function></literal></entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>get token types defined by parser</entry>
|
|
<entry><literal>ts_token_type(3722)</literal></entry>
|
|
<entry><literal>(1,asciiword,"Word, all ASCII") ...</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ts_stat</primary>
|
|
</indexterm>
|
|
<literal><function>ts_stat(<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</>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>get statistics of a <type>tsvector</> column</entry>
|
|
<entry><literal>ts_stat('SELECT vector from apod')</literal></entry>
|
|
<entry><literal>(foo,10,15) ...</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-xml">
|
|
<title>XML Functions</title>
|
|
|
|
<para>
|
|
The functions and function-like expressions described in this
|
|
section operate on values of type <type>xml</type>. Check <xref
|
|
linkend="datatype-xml"> for information about the <type>xml</type>
|
|
type. The function-like expressions <function>xmlparse</function>
|
|
and <function>xmlserialize</function> for converting to and from
|
|
type <type>xml</type> are not repeated here. Use of most of these
|
|
functions requires the installation to have been built
|
|
with <command>configure --with-libxml</>.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title>Producing XML Content</title>
|
|
|
|
<para>
|
|
A set of functions and function-like expressions are available for
|
|
producing XML content from SQL data. As such, they are
|
|
particularly suitable for formatting query results into XML
|
|
documents for processing in client applications.
|
|
</para>
|
|
|
|
<sect3>
|
|
<title><literal>xmlcomment</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmlcomment</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xmlcomment</function>(<replaceable>text</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The function <function>xmlcomment</function> creates an XML value
|
|
containing an XML comment with the specified text as content.
|
|
The text cannot contain <quote><literal>--</literal></quote> or end with a
|
|
<quote><literal>-</literal></quote> so that the resulting construct is a valid
|
|
XML comment. If the argument is null, the result is null.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xmlcomment('hello');
|
|
|
|
xmlcomment
|
|
--------------
|
|
<!--hello-->
|
|
]]></screen>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>xmlconcat</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmlconcat</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xmlconcat</function>(<replaceable>xml</replaceable><optional>, ...</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The function <function>xmlconcat</function> concatenates a list
|
|
of individual XML values to create a single value containing an
|
|
XML content fragment. Null values are omitted; the result is
|
|
only null if there are no nonnull arguments.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xmlconcat('<abc/>', '<bar>foo</bar>');
|
|
|
|
xmlconcat
|
|
----------------------
|
|
<abc/><bar>foo</bar>
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
XML declarations, if present, are combined as follows. If all
|
|
argument values have the same XML version declaration, that
|
|
version is used in the result, else no version is used. If all
|
|
argument values have the standalone declaration value
|
|
<quote>yes</quote>, then that value is used in the result. If
|
|
all argument values have a standalone declaration value and at
|
|
least one is <quote>no</quote>, then that is used in the result.
|
|
Else the result will have no standalone declaration. If the
|
|
result is determined to require a standalone declaration but no
|
|
version declaration, a version declaration with version 1.0 will
|
|
be used because XML requires an XML declaration to contain a
|
|
version declaration. Encoding declarations are ignored and
|
|
removed in all cases.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xmlconcat('<?xml version="1.1"?><foo/>', '<?xml version="1.1" standalone="no"?><bar/>');
|
|
|
|
xmlconcat
|
|
-----------------------------------
|
|
<?xml version="1.1"?><foo/><bar/>
|
|
]]></screen>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>xmlelement</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmlelement</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<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>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>xmlelement</function> expression produces an XML
|
|
element with the given name, attributes, and content.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<screen><![CDATA[
|
|
SELECT xmlelement(name foo);
|
|
|
|
xmlelement
|
|
------------
|
|
<foo/>
|
|
|
|
SELECT xmlelement(name foo, xmlattributes('xyz' as bar));
|
|
|
|
xmlelement
|
|
------------------
|
|
<foo bar="xyz"/>
|
|
|
|
SELECT xmlelement(name foo, xmlattributes(current_date as bar), 'cont', 'ent');
|
|
|
|
xmlelement
|
|
-------------------------------------
|
|
<foo bar="2007-01-26">content</foo>
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
Element and attribute names that are not valid XML names are
|
|
escaped by replacing the offending characters by the sequence
|
|
<literal>_x<replaceable>HHHH</replaceable>_</literal>, where
|
|
<replaceable>HHHH</replaceable> is the character's Unicode
|
|
codepoint in hexadecimal notation. For example:
|
|
<screen><![CDATA[
|
|
SELECT xmlelement(name "foo$bar", xmlattributes('xyz' as "a&b"));
|
|
|
|
xmlelement
|
|
----------------------------------
|
|
<foo_x0024_bar a_x0026_b="xyz"/>
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
An explicit attribute name need not be specified if the attribute
|
|
value is a column reference, in which case the column's name will
|
|
be used as the attribute name by default. In other cases, the
|
|
attribute must be given an explicit name. So this example is
|
|
valid:
|
|
<screen>
|
|
CREATE TABLE test (a xml, b xml);
|
|
SELECT xmlelement(name test, xmlattributes(a, b)) FROM test;
|
|
</screen>
|
|
But these are not:
|
|
<screen>
|
|
SELECT xmlelement(name test, xmlattributes('constant'), a, b) FROM test;
|
|
SELECT xmlelement(name test, xmlattributes(func(a, b))) FROM test;
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
Element content, if specified, will be formatted according to
|
|
its data type. If the content is itself of type <type>xml</type>,
|
|
complex XML documents can be constructed. For example:
|
|
<screen><![CDATA[
|
|
SELECT xmlelement(name foo, xmlattributes('xyz' as bar),
|
|
xmlelement(name abc),
|
|
xmlcomment('test'),
|
|
xmlelement(name xyz));
|
|
|
|
xmlelement
|
|
----------------------------------------------
|
|
<foo bar="xyz"><abc/><!--test--><xyz/></foo>
|
|
]]></screen>
|
|
|
|
Content of other types will be formatted into valid XML character
|
|
data. This means in particular that the characters <, >,
|
|
and & will be converted to entities. Binary data (data type
|
|
<type>bytea</type>) will be represented in base64 or hex
|
|
encoding, depending on the setting of the configuration parameter
|
|
<xref linkend="guc-xmlbinary">. The particular behavior for
|
|
individual data types is expected to evolve in order to align the
|
|
SQL and PostgreSQL data types with the XML Schema specification,
|
|
at which point a more precise description will appear.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>xmlforest</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmlforest</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xmlforest</function>(<replaceable>content</replaceable> <optional>AS <replaceable>name</replaceable></optional> <optional>, ...</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>xmlforest</function> expression produces an XML
|
|
forest (sequence) of elements using the given names and content.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
<screen><![CDATA[
|
|
SELECT xmlforest('abc' AS foo, 123 AS bar);
|
|
|
|
xmlforest
|
|
------------------------------
|
|
<foo>abc</foo><bar>123</bar>
|
|
|
|
|
|
SELECT xmlforest(table_name, column_name)
|
|
FROM information_schema.columns
|
|
WHERE table_schema = 'pg_catalog';
|
|
|
|
xmlforest
|
|
-------------------------------------------------------------------------------------------
|
|
<table_name>pg_authid</table_name><column_name>rolname</column_name>
|
|
<table_name>pg_authid</table_name><column_name>rolsuper</column_name>
|
|
...
|
|
]]></screen>
|
|
|
|
As seen in the second example, the element name can be omitted if
|
|
the content value is a column reference, in which case the column
|
|
name is used by default. Otherwise, a name must be specified.
|
|
</para>
|
|
|
|
<para>
|
|
Element names that are not valid XML names are escaped as shown
|
|
for <function>xmlelement</function> above. Similarly, content
|
|
data is escaped to make valid XML content, unless it is already
|
|
of type <type>xml</type>.
|
|
</para>
|
|
|
|
<para>
|
|
Note that XML forests are not valid XML documents if they consist
|
|
of more than one element, so it might be useful to wrap
|
|
<function>xmlforest</function> expressions in
|
|
<function>xmlelement</function>.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>xmlpi</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmlpi</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xmlpi</function>(name <replaceable>target</replaceable> <optional>, <replaceable>content</replaceable></optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>xmlpi</function> expression creates an XML
|
|
processing instruction. The content, if present, must not
|
|
contain the character sequence <literal>?></literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xmlpi(name php, 'echo "hello world";');
|
|
|
|
xmlpi
|
|
-----------------------------
|
|
<?php echo "hello world";?>
|
|
]]></screen>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title><literal>xmlroot</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmlroot</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xmlroot</function>(<replaceable>xml</replaceable>, version <replaceable>text</replaceable> | no value <optional>, standalone yes|no|no value</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>xmlroot</function> expression alters the properties
|
|
of the root node of an XML value. If a version is specified,
|
|
it replaces the value in the root node's version declaration; if a
|
|
standalone setting is specified, it replaces the value in the
|
|
root node's standalone declaration.
|
|
</para>
|
|
|
|
<para>
|
|
<screen><![CDATA[
|
|
SELECT xmlroot(xmlparse(document '<?xml version="1.1"?><content>abc</content>'),
|
|
version '1.0', standalone yes);
|
|
|
|
xmlroot
|
|
----------------------------------------
|
|
<?xml version="1.0" standalone="yes"?>
|
|
<content>abc</content>
|
|
]]></screen>
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3 id="functions-xml-xmlagg">
|
|
<title><literal>xmlagg</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>xmlagg</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xmlagg</function>(<replaceable>xml</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The function <function>xmlagg</function> is, unlike the other
|
|
functions described here, an aggregate function. It concatenates the
|
|
input values to the aggregate function call,
|
|
much like <function>xmlconcat</function> does, except that concatenation
|
|
occurs across rows rather than across expressions in a single row.
|
|
See <xref linkend="functions-aggregate"> for additional information
|
|
about aggregate functions.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
CREATE TABLE test (y int, x xml);
|
|
INSERT INTO test VALUES (1, '<foo>abc</foo>');
|
|
INSERT INTO test VALUES (2, '<bar/>');
|
|
SELECT xmlagg(x) FROM test;
|
|
xmlagg
|
|
----------------------
|
|
<foo>abc</foo><bar/>
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
To determine the order of the concatenation, an <literal>ORDER BY</>
|
|
clause may be added to the aggregate call as described in
|
|
<xref linkend="syntax-aggregates">. For example:
|
|
|
|
<screen><![CDATA[
|
|
SELECT xmlagg(x ORDER BY y DESC) FROM test;
|
|
xmlagg
|
|
----------------------
|
|
<bar/><foo>abc</foo>
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
The following non-standard approach used to be recommended
|
|
in previous versions, and may still be useful in specific
|
|
cases:
|
|
|
|
<screen><![CDATA[
|
|
SELECT xmlagg(x) FROM (SELECT * FROM test ORDER BY y DESC) AS tab;
|
|
xmlagg
|
|
----------------------
|
|
<bar/><foo>abc</foo>
|
|
]]></screen>
|
|
</para>
|
|
</sect3>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>XML Predicates</title>
|
|
|
|
<para>
|
|
The expressions described in this section check properties
|
|
of <type>xml</type> values.
|
|
</para>
|
|
|
|
<sect3>
|
|
<title>IS DOCUMENT</title>
|
|
|
|
<indexterm>
|
|
<primary>IS DOCUMENT</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<replaceable>xml</replaceable> IS DOCUMENT
|
|
</synopsis>
|
|
|
|
<para>
|
|
The expression <literal>IS DOCUMENT</literal> returns true if the
|
|
argument XML value is a proper XML document, false if it is not
|
|
(that is, it is a content fragment), or null if the argument is
|
|
null. See <xref linkend="datatype-xml"> about the difference
|
|
between documents and content fragments.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title>XMLEXISTS</title>
|
|
|
|
<indexterm>
|
|
<primary>XMLEXISTS</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>XMLEXISTS</function>(<replaceable>text</replaceable> PASSING <optional>BY REF</optional> <replaceable>xml</replaceable> <optional>BY REF</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The function <function>xmlexists</function> returns true if the
|
|
XPath expression in the first argument returns any nodes, and
|
|
false otherwise. (If either argument is null, the result is
|
|
null.)
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xmlexists('//town[text() = ''Toronto'']' PASSING BY REF '<towns><town>Toronto</town><town>Ottawa</town></towns>');
|
|
|
|
xmlexists
|
|
------------
|
|
t
|
|
(1 row)
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>BY REF</literal> clauses have no effect in
|
|
PostgreSQL, but are allowed for SQL conformance and compatibility
|
|
with other implementations. Per SQL standard, the
|
|
first <literal>BY REF</literal> is required, the second is
|
|
optional. Also note that the SQL standard specifies
|
|
the <function>xmlexists</function> construct to take an XQuery
|
|
expression as first argument, but PostgreSQL currently only
|
|
supports XPath, which is a subset of XQuery.
|
|
</para>
|
|
</sect3>
|
|
|
|
<sect3>
|
|
<title>xml_is_well_formed</title>
|
|
|
|
<indexterm>
|
|
<primary>xml_is_well_formed</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>xml_is_well_formed_document</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>xml_is_well_formed_content</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xml_is_well_formed</function>(<replaceable>text</replaceable>)
|
|
<function>xml_is_well_formed_document</function>(<replaceable>text</replaceable>)
|
|
<function>xml_is_well_formed_content</function>(<replaceable>text</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
These functions check whether a <type>text</> string is well-formed XML,
|
|
returning a boolean result.
|
|
<function>xml_is_well_formed_document</function> checks for a well-formed
|
|
document, while <function>xml_is_well_formed_content</function> checks
|
|
for well-formed content. <function>xml_is_well_formed</function> does
|
|
the former if the <xref linkend="guc-xmloption"> configuration
|
|
parameter is set to <literal>DOCUMENT</>, or the latter if it is set to
|
|
<literal>CONTENT</>. This means that
|
|
<function>xml_is_well_formed</function> is useful for seeing whether
|
|
a simple cast to type <type>xml</> will succeed, whereas the other two
|
|
functions are useful for seeing whether the corresponding variants of
|
|
<function>XMLPARSE</> will succeed.
|
|
</para>
|
|
|
|
<para>
|
|
Examples:
|
|
|
|
<screen><![CDATA[
|
|
SET xmloption TO DOCUMENT;
|
|
SELECT xml_is_well_formed('<>');
|
|
xml_is_well_formed
|
|
--------------------
|
|
f
|
|
(1 row)
|
|
|
|
SELECT xml_is_well_formed('<abc/>');
|
|
xml_is_well_formed
|
|
--------------------
|
|
t
|
|
(1 row)
|
|
|
|
SET xmloption TO CONTENT;
|
|
SELECT xml_is_well_formed('abc');
|
|
xml_is_well_formed
|
|
--------------------
|
|
t
|
|
(1 row)
|
|
|
|
SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</pg:foo>');
|
|
xml_is_well_formed_document
|
|
-----------------------------
|
|
t
|
|
(1 row)
|
|
|
|
SELECT xml_is_well_formed_document('<pg:foo xmlns:pg="http://postgresql.org/stuff">bar</my:foo>');
|
|
xml_is_well_formed_document
|
|
-----------------------------
|
|
f
|
|
(1 row)
|
|
]]></screen>
|
|
|
|
The last example shows that the checks include whether
|
|
namespaces are correctly matched.
|
|
</para>
|
|
</sect3>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-xml-processing">
|
|
<title>Processing XML</title>
|
|
|
|
<indexterm>
|
|
<primary>XPath</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
To process values of data type <type>xml</type>, PostgreSQL offers
|
|
the functions <function>xpath</function> and
|
|
<function>xpath_exists</function>, which evaluate XPath 1.0
|
|
expressions.
|
|
</para>
|
|
|
|
<synopsis>
|
|
<function>xpath</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The function <function>xpath</function> evaluates the XPath
|
|
expression <replaceable>xpath</replaceable> (a <type>text</> value)
|
|
against the XML value
|
|
<replaceable>xml</replaceable>. It returns an array of XML values
|
|
corresponding to the node set produced by the XPath expression.
|
|
</para>
|
|
|
|
<para>
|
|
The second argument must be a well formed XML document. In particular,
|
|
it must have a single root node element.
|
|
</para>
|
|
|
|
<para>
|
|
The optional third argument of the function is an array of namespace
|
|
mappings. This array should be a two-dimensional <type>text</> array with
|
|
the length of the second axis being equal to 2 (i.e., it should be an
|
|
array of arrays, each of which consists of exactly 2 elements).
|
|
The first element of each array entry is the namespace name (alias), the
|
|
second the namespace URI. It is not required that aliases provided in
|
|
this array be the same as those being used in the XML document itself (in
|
|
other words, both in the XML document and in the <function>xpath</function>
|
|
function context, aliases are <emphasis>local</>).
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xpath('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
|
|
ARRAY[ARRAY['my', 'http://example.com']]);
|
|
|
|
xpath
|
|
--------
|
|
{test}
|
|
(1 row)
|
|
]]></screen>
|
|
</para>
|
|
|
|
<para>
|
|
To deal with default (anonymous) namespaces, do something like this:
|
|
<screen><![CDATA[
|
|
SELECT xpath('//mydefns:b/text()', '<a xmlns="http://example.com"><b>test</b></a>',
|
|
ARRAY[ARRAY['mydefns', 'http://example.com']]);
|
|
|
|
xpath
|
|
--------
|
|
{test}
|
|
(1 row)
|
|
]]></screen>
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>xpath_exists</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>xpath_exists</function>(<replaceable>xpath</replaceable>, <replaceable>xml</replaceable> <optional>, <replaceable>nsarray</replaceable></optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The function <function>xpath_exists</function> is a specialized form
|
|
of the <function>xpath</function> function. Instead of returning the
|
|
individual XML values that satisfy the XPath, this function returns a
|
|
boolean indicating whether the query was satisfied or not. This
|
|
function is equivalent to the standard <literal>XMLEXISTS</> predicate,
|
|
except that it also offers support for a namespace mapping argument.
|
|
</para>
|
|
|
|
<para>
|
|
Example:
|
|
<screen><![CDATA[
|
|
SELECT xpath_exists('/my:a/text()', '<my:a xmlns:my="http://example.com">test</my:a>',
|
|
ARRAY[ARRAY['my', 'http://example.com']]);
|
|
|
|
xpath_exists
|
|
--------------
|
|
t
|
|
(1 row)
|
|
]]></screen>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="functions-xml-mapping">
|
|
<title>Mapping Tables to XML</title>
|
|
|
|
<indexterm zone="functions-xml-mapping">
|
|
<primary>XML export</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The following functions map the contents of relational tables to
|
|
XML values. They can be thought of as XML export functionality:
|
|
<synopsis>
|
|
table_to_xml(tbl regclass, nulls boolean, tableforest boolean, targetns text)
|
|
query_to_xml(query text, nulls boolean, tableforest boolean, targetns text)
|
|
cursor_to_xml(cursor refcursor, count int, nulls boolean,
|
|
tableforest boolean, targetns text)
|
|
</synopsis>
|
|
The return type of each function is <type>xml</type>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>table_to_xml</function> maps the content of the named
|
|
table, passed as parameter <parameter>tbl</parameter>. The
|
|
<type>regclass</type> type accepts strings identifying tables using the
|
|
usual notation, including optional schema qualifications and
|
|
double quotes. <function>query_to_xml</function> executes the
|
|
query whose text is passed as parameter
|
|
<parameter>query</parameter> and maps the result set.
|
|
<function>cursor_to_xml</function> fetches the indicated number of
|
|
rows from the cursor specified by the parameter
|
|
<parameter>cursor</parameter>. This variant is recommended if
|
|
large tables have to be mapped, because the result value is built
|
|
up in memory by each function.
|
|
</para>
|
|
|
|
<para>
|
|
If <parameter>tableforest</parameter> is false, then the resulting
|
|
XML document looks like this:
|
|
<screen><![CDATA[
|
|
<tablename>
|
|
<row>
|
|
<columnname1>data</columnname1>
|
|
<columnname2>data</columnname2>
|
|
</row>
|
|
|
|
<row>
|
|
...
|
|
</row>
|
|
|
|
...
|
|
</tablename>
|
|
]]></screen>
|
|
|
|
If <parameter>tableforest</parameter> is true, the result is an
|
|
XML content fragment that looks like this:
|
|
<screen><![CDATA[
|
|
<tablename>
|
|
<columnname1>data</columnname1>
|
|
<columnname2>data</columnname2>
|
|
</tablename>
|
|
|
|
<tablename>
|
|
...
|
|
</tablename>
|
|
|
|
...
|
|
]]></screen>
|
|
|
|
If no table name is available, that is, when mapping a query or a
|
|
cursor, the string <literal>table</literal> is used in the first
|
|
format, <literal>row</literal> in the second format.
|
|
</para>
|
|
|
|
<para>
|
|
The choice between these formats is up to the user. The first
|
|
format is a proper XML document, which will be important in many
|
|
applications. The second format tends to be more useful in the
|
|
<function>cursor_to_xml</function> function if the result values are to be
|
|
reassembled into one document later on. The functions for
|
|
producing XML content discussed above, in particular
|
|
<function>xmlelement</function>, can be used to alter the results
|
|
to taste.
|
|
</para>
|
|
|
|
<para>
|
|
The data values are mapped in the same way as described for the
|
|
function <function>xmlelement</function> above.
|
|
</para>
|
|
|
|
<para>
|
|
The parameter <parameter>nulls</parameter> determines whether null
|
|
values should be included in the output. If true, null values in
|
|
columns are represented as:
|
|
<screen><![CDATA[
|
|
<columnname xsi:nil="true"/>
|
|
]]></screen>
|
|
where <literal>xsi</literal> is the XML namespace prefix for XML
|
|
Schema Instance. An appropriate namespace declaration will be
|
|
added to the result value. If false, columns containing null
|
|
values are simply omitted from the output.
|
|
</para>
|
|
|
|
<para>
|
|
The parameter <parameter>targetns</parameter> specifies the
|
|
desired XML namespace of the result. If no particular namespace
|
|
is wanted, an empty string should be passed.
|
|
</para>
|
|
|
|
<para>
|
|
The following functions return XML Schema documents describing the
|
|
mappings performed by the corresponding functions above:
|
|
<synopsis>
|
|
table_to_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
|
|
query_to_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
|
|
cursor_to_xmlschema(cursor refcursor, nulls boolean, tableforest boolean, targetns text)
|
|
</synopsis>
|
|
It is essential that the same parameters are passed in order to
|
|
obtain matching XML data mappings and XML Schema documents.
|
|
</para>
|
|
|
|
<para>
|
|
The following functions produce XML data mappings and the
|
|
corresponding XML Schema in one document (or forest), linked
|
|
together. They can be useful where self-contained and
|
|
self-describing results are wanted:
|
|
<synopsis>
|
|
table_to_xml_and_xmlschema(tbl regclass, nulls boolean, tableforest boolean, targetns text)
|
|
query_to_xml_and_xmlschema(query text, nulls boolean, tableforest boolean, targetns text)
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
In addition, the following functions are available to produce
|
|
analogous mappings of entire schemas or the entire current
|
|
database:
|
|
<synopsis>
|
|
schema_to_xml(schema name, nulls boolean, tableforest boolean, targetns text)
|
|
schema_to_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
|
|
schema_to_xml_and_xmlschema(schema name, nulls boolean, tableforest boolean, targetns text)
|
|
|
|
database_to_xml(nulls boolean, tableforest boolean, targetns text)
|
|
database_to_xmlschema(nulls boolean, tableforest boolean, targetns text)
|
|
database_to_xml_and_xmlschema(nulls boolean, tableforest boolean, targetns text)
|
|
</synopsis>
|
|
|
|
Note that these potentially produce a lot of data, which needs to
|
|
be built up in memory. When requesting content mappings of large
|
|
schemas or databases, it might be worthwhile to consider mapping the
|
|
tables separately instead, possibly even through a cursor.
|
|
</para>
|
|
|
|
<para>
|
|
The result of a schema content mapping looks like this:
|
|
|
|
<screen><![CDATA[
|
|
<schemaname>
|
|
|
|
table1-mapping
|
|
|
|
table2-mapping
|
|
|
|
...
|
|
|
|
</schemaname>]]></screen>
|
|
|
|
where the format of a table mapping depends on the
|
|
<parameter>tableforest</parameter> parameter as explained above.
|
|
</para>
|
|
|
|
<para>
|
|
The result of a database content mapping looks like this:
|
|
|
|
<screen><![CDATA[
|
|
<dbname>
|
|
|
|
<schema1name>
|
|
...
|
|
</schema1name>
|
|
|
|
<schema2name>
|
|
...
|
|
</schema2name>
|
|
|
|
...
|
|
|
|
</dbname>]]></screen>
|
|
|
|
where the schema mapping is as above.
|
|
</para>
|
|
|
|
<para>
|
|
As an example of using the output produced by these functions,
|
|
<xref linkend="xslt-xml-html"> shows an XSLT stylesheet that
|
|
converts the output of
|
|
<function>table_to_xml_and_xmlschema</function> to an HTML
|
|
document containing a tabular rendition of the table data. In a
|
|
similar manner, the results from these functions can be
|
|
converted into other XML-based formats.
|
|
</para>
|
|
|
|
<figure id="xslt-xml-html">
|
|
<title>XSLT Stylesheet for Converting SQL/XML Output to HTML</title>
|
|
<programlisting><![CDATA[
|
|
<?xml version="1.0"?>
|
|
<xsl:stylesheet version="1.0"
|
|
xmlns:xsl="http://www.w3.org/1999/XSL/Transform"
|
|
xmlns:xsd="http://www.w3.org/2001/XMLSchema"
|
|
xmlns="http://www.w3.org/1999/xhtml"
|
|
>
|
|
|
|
<xsl:output method="xml"
|
|
doctype-system="http://www.w3.org/TR/xhtml1/DTD/xhtml1-strict.dtd"
|
|
doctype-public="-//W3C/DTD XHTML 1.0 Strict//EN"
|
|
indent="yes"/>
|
|
|
|
<xsl:template match="/*">
|
|
<xsl:variable name="schema" select="//xsd:schema"/>
|
|
<xsl:variable name="tabletypename"
|
|
select="$schema/xsd:element[@name=name(current())]/@type"/>
|
|
<xsl:variable name="rowtypename"
|
|
select="$schema/xsd:complexType[@name=$tabletypename]/xsd:sequence/xsd:element[@name='row']/@type"/>
|
|
|
|
<html>
|
|
<head>
|
|
<title><xsl:value-of select="name(current())"/></title>
|
|
</head>
|
|
<body>
|
|
<table>
|
|
<tr>
|
|
<xsl:for-each select="$schema/xsd:complexType[@name=$rowtypename]/xsd:sequence/xsd:element/@name">
|
|
<th><xsl:value-of select="."/></th>
|
|
</xsl:for-each>
|
|
</tr>
|
|
|
|
<xsl:for-each select="row">
|
|
<tr>
|
|
<xsl:for-each select="*">
|
|
<td><xsl:value-of select="."/></td>
|
|
</xsl:for-each>
|
|
</tr>
|
|
</xsl:for-each>
|
|
</table>
|
|
</body>
|
|
</html>
|
|
</xsl:template>
|
|
|
|
</xsl:stylesheet>
|
|
]]></programlisting>
|
|
</figure>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-sequence">
|
|
<title>Sequence Manipulation Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>sequence</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>nextval</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>currval</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>lastval</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>setval</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes <productname>PostgreSQL</productname>'s
|
|
functions for operating on <firstterm>sequence objects</firstterm>.
|
|
Sequence objects (also called sequence generators or just
|
|
sequences) are special single-row tables created with <xref
|
|
linkend="sql-createsequence">.
|
|
A sequence object is usually used to generate unique identifiers
|
|
for rows of a table. The sequence functions, listed in <xref
|
|
linkend="functions-sequence-table">, provide simple, multiuser-safe
|
|
methods for obtaining successive sequence values from sequence
|
|
objects.
|
|
</para>
|
|
|
|
<table id="functions-sequence-table">
|
|
<title>Sequence Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Function</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>currval(<type>regclass</type>)</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Return value most recently obtained with
|
|
<function>nextval</function> for specified sequence</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>lastval()</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Return value most recently obtained with
|
|
<function>nextval</function> for any sequence</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>nextval(<type>regclass</type>)</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Advance sequence and return new value</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>)</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Set sequence's current value</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>setval(<type>regclass</type>, <type>bigint</type>, <type>boolean</type>)</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Set sequence's current value and <literal>is_called</literal> flag</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The sequence to be operated on by a sequence function is specified by
|
|
a <type>regclass</> argument, which is simply the OID of the sequence in the
|
|
<structname>pg_class</> system catalog. You do not have to look up the
|
|
OID by hand, however, since the <type>regclass</> data type's input
|
|
converter will do the work for you. Just write the sequence name enclosed
|
|
in single quotes so that it looks like a literal constant. For
|
|
compatibility with the handling of ordinary
|
|
<acronym>SQL</acronym> names, the string will be converted to lower case
|
|
unless it contains double quotes around the sequence name. Thus:
|
|
<programlisting>
|
|
nextval('foo') <lineannotation>operates on sequence <literal>foo</literal></>
|
|
nextval('FOO') <lineannotation>operates on sequence <literal>foo</literal></>
|
|
nextval('"Foo"') <lineannotation>operates on sequence <literal>Foo</literal></>
|
|
</programlisting>
|
|
The sequence name can be schema-qualified if necessary:
|
|
<programlisting>
|
|
nextval('myschema.foo') <lineannotation>operates on <literal>myschema.foo</literal></>
|
|
nextval('"myschema".foo') <lineannotation>same as above</lineannotation>
|
|
nextval('foo') <lineannotation>searches search path for <literal>foo</literal></>
|
|
</programlisting>
|
|
See <xref linkend="datatype-oid"> for more information about
|
|
<type>regclass</>.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Before <productname>PostgreSQL</productname> 8.1, the arguments of the
|
|
sequence functions were of type <type>text</>, not <type>regclass</>, and
|
|
the above-described conversion from a text string to an OID value would
|
|
happen at run time during each call. For backwards compatibility, this
|
|
facility still exists, but internally it is now handled as an implicit
|
|
coercion from <type>text</> to <type>regclass</> before the function is
|
|
invoked.
|
|
</para>
|
|
|
|
<para>
|
|
When you write the argument of a sequence function as an unadorned
|
|
literal string, it becomes a constant of type <type>regclass</>.
|
|
Since this is really just an OID, it will track the originally
|
|
identified sequence despite later renaming, schema reassignment,
|
|
etc. This <quote>early binding</> behavior is usually desirable for
|
|
sequence references in column defaults and views. But sometimes you might
|
|
want <quote>late binding</> where the sequence reference is resolved
|
|
at run time. To get late-binding behavior, force the constant to be
|
|
stored as a <type>text</> constant instead of <type>regclass</>:
|
|
<programlisting>
|
|
nextval('foo'::text) <lineannotation><literal>foo</literal> is looked up at runtime</>
|
|
</programlisting>
|
|
Note that late binding was the only behavior supported in
|
|
<productname>PostgreSQL</productname> releases before 8.1, so you
|
|
might need to do this to preserve the semantics of old applications.
|
|
</para>
|
|
|
|
<para>
|
|
Of course, the argument of a sequence function can be an expression
|
|
as well as a constant. If it is a text expression then the implicit
|
|
coercion will result in a run-time lookup.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The available sequence functions are:
|
|
|
|
<variablelist>
|
|
<varlistentry>
|
|
<term><function>nextval</function></term>
|
|
<listitem>
|
|
<para>
|
|
Advance the sequence object to its next value and return that
|
|
value. This is done atomically: even if multiple sessions
|
|
execute <function>nextval</function> concurrently, each will safely receive
|
|
a distinct sequence value.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><function>currval</function></term>
|
|
<listitem>
|
|
<para>
|
|
Return the value most recently obtained by <function>nextval</function>
|
|
for this sequence in the current session. (An error is
|
|
reported if <function>nextval</function> has never been called for this
|
|
sequence in this session.) Because this is returning
|
|
a session-local value, it gives a predictable answer whether or not
|
|
other sessions have executed <function>nextval</function> since the
|
|
current session did.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><function>lastval</function></term>
|
|
<listitem>
|
|
<para>
|
|
Return the value most recently returned by
|
|
<function>nextval</> in the current session. This function is
|
|
identical to <function>currval</function>, except that instead
|
|
of taking the sequence name as an argument it fetches the
|
|
value of the last sequence used by <function>nextval</function>
|
|
in the current session. It is an error to call
|
|
<function>lastval</function> if <function>nextval</function>
|
|
has not yet been called in the current session.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
|
|
<varlistentry>
|
|
<term><function>setval</function></term>
|
|
<listitem>
|
|
<para>
|
|
Reset the sequence object's counter value. The two-parameter
|
|
form sets the sequence's <literal>last_value</literal> field to the
|
|
specified value and sets its <literal>is_called</literal> field to
|
|
<literal>true</literal>, meaning that the next
|
|
<function>nextval</function> will advance the sequence before
|
|
returning a value. The value reported by <function>currval</> is
|
|
also set to the specified value. In the three-parameter form,
|
|
<literal>is_called</literal> can be set to either <literal>true</literal>
|
|
or <literal>false</literal>. <literal>true</> has the same effect as
|
|
the two-parameter form. If it is set to <literal>false</literal>, the
|
|
next <function>nextval</function> will return exactly the specified
|
|
value, and sequence advancement commences with the following
|
|
<function>nextval</function>. Furthermore, the value reported by
|
|
<function>currval</> is not changed in this case (this is a change
|
|
from pre-8.3 behavior). For example,
|
|
|
|
<screen>
|
|
SELECT setval('foo', 42); <lineannotation>Next <function>nextval</> will return 43</lineannotation>
|
|
SELECT setval('foo', 42, true); <lineannotation>Same as above</lineannotation>
|
|
SELECT setval('foo', 42, false); <lineannotation>Next <function>nextval</> will return 42</lineannotation>
|
|
</screen>
|
|
|
|
The result returned by <function>setval</function> is just the value of its
|
|
second argument.
|
|
</para>
|
|
</listitem>
|
|
</varlistentry>
|
|
</variablelist>
|
|
</para>
|
|
|
|
<para>
|
|
If a sequence object has been created with default parameters,
|
|
successive <function>nextval</function> calls will return successive values
|
|
beginning with 1. Other behaviors can be obtained by using
|
|
special parameters in the <xref linkend="sql-createsequence"> command;
|
|
see its command reference page for more information.
|
|
</para>
|
|
|
|
<important>
|
|
<para>
|
|
To avoid blocking concurrent transactions that obtain numbers from the
|
|
same sequence, a <function>nextval</function> operation is never rolled back;
|
|
that is, once a value has been fetched it is considered used, even if the
|
|
transaction that did the <function>nextval</function> later aborts. This means
|
|
that aborted transactions might leave unused <quote>holes</quote> in the
|
|
sequence of assigned values. <function>setval</function> operations are never
|
|
rolled back, either.
|
|
</para>
|
|
</important>
|
|
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-conditional">
|
|
<title>Conditional Expressions</title>
|
|
|
|
<indexterm>
|
|
<primary>CASE</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>conditional expression</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes the <acronym>SQL</acronym>-compliant conditional expressions
|
|
available in <productname>PostgreSQL</productname>.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
If your needs go beyond the capabilities of these conditional
|
|
expressions, you might want to consider writing a stored procedure
|
|
in a more expressive programming language.
|
|
</para>
|
|
</tip>
|
|
|
|
<sect2>
|
|
<title><literal>CASE</></title>
|
|
|
|
<para>
|
|
The <acronym>SQL</acronym> <token>CASE</token> expression is a
|
|
generic conditional expression, similar to if/else statements in
|
|
other programming languages:
|
|
|
|
<synopsis>
|
|
CASE WHEN <replaceable>condition</replaceable> THEN <replaceable>result</replaceable>
|
|
<optional>WHEN ...</optional>
|
|
<optional>ELSE <replaceable>result</replaceable></optional>
|
|
END
|
|
</synopsis>
|
|
|
|
<token>CASE</token> clauses can be used wherever
|
|
an expression is valid. Each <replaceable>condition</replaceable> is an
|
|
expression that returns a <type>boolean</type> result. If the condition's
|
|
result is true, the value of the <token>CASE</token> expression is the
|
|
<replaceable>result</replaceable> that follows the condition, and the
|
|
remainder of the <token>CASE</token> expression is not processed. If the
|
|
condition's result is not true, any subsequent <token>WHEN</token> clauses
|
|
are examined in the same manner. If no <token>WHEN</token>
|
|
<replaceable>condition</replaceable> yields true, the value of the
|
|
<token>CASE</> expression is the <replaceable>result</replaceable> of the
|
|
<token>ELSE</token> clause. If the <token>ELSE</token> clause is
|
|
omitted and no condition is true, the result is null.
|
|
</para>
|
|
|
|
<para>
|
|
An example:
|
|
<screen>
|
|
SELECT * FROM test;
|
|
|
|
a
|
|
---
|
|
1
|
|
2
|
|
3
|
|
|
|
|
|
SELECT a,
|
|
CASE WHEN a=1 THEN 'one'
|
|
WHEN a=2 THEN 'two'
|
|
ELSE 'other'
|
|
END
|
|
FROM test;
|
|
|
|
a | case
|
|
---+-------
|
|
1 | one
|
|
2 | two
|
|
3 | other
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
The data types of all the <replaceable>result</replaceable>
|
|
expressions must be convertible to a single output type.
|
|
See <xref linkend="typeconv-union-case"> for more details.
|
|
</para>
|
|
|
|
<para>
|
|
There is a <quote>simple</> form of <token>CASE</token> expression
|
|
that is a variant of the general form above:
|
|
|
|
<synopsis>
|
|
CASE <replaceable>expression</replaceable>
|
|
WHEN <replaceable>value</replaceable> THEN <replaceable>result</replaceable>
|
|
<optional>WHEN ...</optional>
|
|
<optional>ELSE <replaceable>result</replaceable></optional>
|
|
END
|
|
</synopsis>
|
|
|
|
The first
|
|
<replaceable>expression</replaceable> is computed, then compared to
|
|
each of the <replaceable>value</replaceable> expressions in the
|
|
<token>WHEN</token> clauses until one is found that is equal to it. If
|
|
no match is found, the <replaceable>result</replaceable> of the
|
|
<token>ELSE</token> clause (or a null value) is returned. This is similar
|
|
to the <function>switch</function> statement in C.
|
|
</para>
|
|
|
|
<para>
|
|
The example above can be written using the simple
|
|
<token>CASE</token> syntax:
|
|
<screen>
|
|
SELECT a,
|
|
CASE a WHEN 1 THEN 'one'
|
|
WHEN 2 THEN 'two'
|
|
ELSE 'other'
|
|
END
|
|
FROM test;
|
|
|
|
a | case
|
|
---+-------
|
|
1 | one
|
|
2 | two
|
|
3 | other
|
|
</screen>
|
|
</para>
|
|
|
|
<para>
|
|
A <token>CASE</token> expression does not evaluate any subexpressions
|
|
that are not needed to determine the result. For example, this is a
|
|
possible way of avoiding a division-by-zero failure:
|
|
<programlisting>
|
|
SELECT ... WHERE CASE WHEN x <> 0 THEN y/x > 1.5 ELSE false END;
|
|
</programlisting>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>COALESCE</></title>
|
|
|
|
<indexterm>
|
|
<primary>COALESCE</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>NVL</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>IFNULL</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>COALESCE</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>COALESCE</function> function returns the first of its
|
|
arguments that is not null. Null is returned only if all arguments
|
|
are null. It is often used to substitute a default value for
|
|
null values when data is retrieved for display, for example:
|
|
<programlisting>
|
|
SELECT COALESCE(description, short_description, '(none)') ...
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
Like a <token>CASE</token> expression, <function>COALESCE</function> only
|
|
evaluates the arguments that are needed to determine the result;
|
|
that is, arguments to the right of the first non-null argument are
|
|
not evaluated. This SQL-standard function provides capabilities similar
|
|
to <function>NVL</> and <function>IFNULL</>, which are used in some other
|
|
database systems.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>NULLIF</></title>
|
|
|
|
<indexterm>
|
|
<primary>NULLIF</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>NULLIF</function>(<replaceable>value1</replaceable>, <replaceable>value2</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>NULLIF</function> function returns a null value if
|
|
<replaceable>value1</replaceable> equals <replaceable>value2</replaceable>;
|
|
otherwise it returns <replaceable>value1</replaceable>.
|
|
This can be used to perform the inverse operation of the
|
|
<function>COALESCE</function> example given above:
|
|
<programlisting>
|
|
SELECT NULLIF(value, '(none)') ...
|
|
</programlisting>
|
|
</para>
|
|
<para>
|
|
In this example, if <literal>value</literal> is <literal>(none)</>,
|
|
null is returned, otherwise the value of <literal>value</literal>
|
|
is returned.
|
|
</para>
|
|
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>GREATEST</literal> and <literal>LEAST</literal></title>
|
|
|
|
<indexterm>
|
|
<primary>GREATEST</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>LEAST</primary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<function>GREATEST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
|
|
</synopsis>
|
|
<synopsis>
|
|
<function>LEAST</function>(<replaceable>value</replaceable> <optional>, ...</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The <function>GREATEST</> and <function>LEAST</> functions select the
|
|
largest or smallest value from a list of any number of expressions.
|
|
The expressions must all be convertible to a common data type, which
|
|
will be the type of the result
|
|
(see <xref linkend="typeconv-union-case"> for details). NULL values
|
|
in the list are ignored. The result will be NULL only if all the
|
|
expressions evaluate to NULL.
|
|
</para>
|
|
|
|
<para>
|
|
Note that <function>GREATEST</> and <function>LEAST</> are not in
|
|
the SQL standard, but are a common extension. Some other databases
|
|
make them return NULL if any argument is NULL, rather than only when
|
|
all are NULL.
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="functions-array">
|
|
<title>Array Functions and Operators</title>
|
|
|
|
<para>
|
|
<xref linkend="array-operators-table"> shows the operators
|
|
available for array types.
|
|
</para>
|
|
|
|
<table id="array-operators-table">
|
|
<title>Array Operators</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Operator</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry> <literal>=</literal> </entry>
|
|
<entry>equal</entry>
|
|
<entry><literal>ARRAY[1.1,2.1,3.1]::int[] = ARRAY[1,2,3]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><></literal> </entry>
|
|
<entry>not equal</entry>
|
|
<entry><literal>ARRAY[1,2,3] <> ARRAY[1,2,4]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><</literal> </entry>
|
|
<entry>less than</entry>
|
|
<entry><literal>ARRAY[1,2,3] < ARRAY[1,2,4]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>></literal> </entry>
|
|
<entry>greater than</entry>
|
|
<entry><literal>ARRAY[1,4,3] > ARRAY[1,2,4]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><=</literal> </entry>
|
|
<entry>less than or equal</entry>
|
|
<entry><literal>ARRAY[1,2,3] <= ARRAY[1,2,3]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>>=</literal> </entry>
|
|
<entry>greater than or equal</entry>
|
|
<entry><literal>ARRAY[1,4,3] >= ARRAY[1,4,3]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>@></literal> </entry>
|
|
<entry>contains</entry>
|
|
<entry><literal>ARRAY[1,4,3] @> ARRAY[3,1]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal><@</literal> </entry>
|
|
<entry>is contained by</entry>
|
|
<entry><literal>ARRAY[2,7] <@ ARRAY[1,7,4,2,6]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>&&</literal> </entry>
|
|
<entry>overlap (have elements in common)</entry>
|
|
<entry><literal>ARRAY[1,4,3] && ARRAY[2,1]</literal></entry>
|
|
<entry><literal>t</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>||</literal> </entry>
|
|
<entry>array-to-array concatenation</entry>
|
|
<entry><literal>ARRAY[1,2,3] || ARRAY[4,5,6]</literal></entry>
|
|
<entry><literal>{1,2,3,4,5,6}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>||</literal> </entry>
|
|
<entry>array-to-array concatenation</entry>
|
|
<entry><literal>ARRAY[1,2,3] || ARRAY[[4,5,6],[7,8,9]]</literal></entry>
|
|
<entry><literal>{{1,2,3},{4,5,6},{7,8,9}}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>||</literal> </entry>
|
|
<entry>element-to-array concatenation</entry>
|
|
<entry><literal>3 || ARRAY[4,5,6]</literal></entry>
|
|
<entry><literal>{3,4,5,6}</literal></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry> <literal>||</literal> </entry>
|
|
<entry>array-to-element concatenation</entry>
|
|
<entry><literal>ARRAY[4,5,6] || 7</literal></entry>
|
|
<entry><literal>{4,5,6,7}</literal></entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Array comparisons compare the array contents element-by-element,
|
|
using the default B-tree comparison function for the element data type.
|
|
In multidimensional arrays the elements are visited in row-major order
|
|
(last subscript varies most rapidly).
|
|
If the contents of two arrays are equal but the dimensionality is
|
|
different, the first difference in the dimensionality information
|
|
determines the sort order. (This is a change from versions of
|
|
<productname>PostgreSQL</> prior to 8.2: older versions would claim
|
|
that two arrays with the same contents were equal, even if the
|
|
number of dimensions or subscript ranges were different.)
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="arrays"> for more details about array operator
|
|
behavior.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="array-functions-table"> shows the functions
|
|
available for use with array types. See <xref linkend="arrays">
|
|
for more information and examples of the use of these functions.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>array_append</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_cat</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_ndims</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_dims</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_fill</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_length</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_lower</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_prepend</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_to_string</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>array_upper</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>string_to_array</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>unnest</primary>
|
|
</indexterm>
|
|
|
|
<table id="array-functions-table">
|
|
<title>Array Functions</title>
|
|
<tgroup cols="5">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
<entry>Example</entry>
|
|
<entry>Result</entry>
|
|
</row>
|
|
</thead>
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_append</function>(<type>anyarray</type>, <type>anyelement</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>anyarray</type></entry>
|
|
<entry>append an element to the end of an array</entry>
|
|
<entry><literal>array_append(ARRAY[1,2], 3)</literal></entry>
|
|
<entry><literal>{1,2,3}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_cat</function>(<type>anyarray</type>, <type>anyarray</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>anyarray</type></entry>
|
|
<entry>concatenate two arrays</entry>
|
|
<entry><literal>array_cat(ARRAY[1,2,3], ARRAY[4,5])</literal></entry>
|
|
<entry><literal>{1,2,3,4,5}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_ndims</function>(<type>anyarray</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>returns the number of dimensions of the array</entry>
|
|
<entry><literal>array_ndims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
|
|
<entry><literal>2</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_dims</function>(<type>anyarray</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>returns a text representation of array's dimensions</entry>
|
|
<entry><literal>array_dims(ARRAY[[1,2,3], [4,5,6]])</literal></entry>
|
|
<entry><literal>[1:2][1:3]</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_fill</function>(<type>anyelement</type>, <type>int[]</type>,
|
|
<optional>, <type>int[]</type></optional>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>anyarray</type></entry>
|
|
<entry>returns an array initialized with supplied value and
|
|
dimensions, optionally with lower bounds other than 1</entry>
|
|
<entry><literal>array_fill(7, ARRAY[3], ARRAY[2])</literal></entry>
|
|
<entry><literal>[2:4]={7,7,7}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_length</function>(<type>anyarray</type>, <type>int</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>returns the length of the requested array dimension</entry>
|
|
<entry><literal>array_length(array[1,2,3], 1)</literal></entry>
|
|
<entry><literal>3</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_lower</function>(<type>anyarray</type>, <type>int</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>returns lower bound of the requested array dimension</entry>
|
|
<entry><literal>array_lower('[0:2]={1,2,3}'::int[], 1)</literal></entry>
|
|
<entry><literal>0</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_prepend</function>(<type>anyelement</type>, <type>anyarray</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>anyarray</type></entry>
|
|
<entry>append an element to the beginning of an array</entry>
|
|
<entry><literal>array_prepend(1, ARRAY[2,3])</literal></entry>
|
|
<entry><literal>{1,2,3}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_to_string</function>(<type>anyarray</type>, <type>text</type> <optional>, <type>text</type></optional>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>concatenates array elements using supplied delimiter and
|
|
optional null string</entry>
|
|
<entry><literal>array_to_string(ARRAY[1, 2, 3, NULL, 5], ',', '*')</literal></entry>
|
|
<entry><literal>1,2,3,*,5</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>array_upper</function>(<type>anyarray</type>, <type>int</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>returns upper bound of the requested array dimension</entry>
|
|
<entry><literal>array_upper(ARRAY[1,8,3,7], 1)</literal></entry>
|
|
<entry><literal>4</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>string_to_array</function>(<type>text</type>, <type>text</type> <optional>, <type>text</type></optional>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>text[]</type></entry>
|
|
<entry>splits string into array elements using supplied delimiter and
|
|
optional null string</entry>
|
|
<entry><literal>string_to_array('xx~^~yy~^~zz', '~^~', 'yy')</literal></entry>
|
|
<entry><literal>{xx,NULL,zz}</literal></entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal>
|
|
<function>unnest</function>(<type>anyarray</type>)
|
|
</literal>
|
|
</entry>
|
|
<entry><type>setof anyelement</type></entry>
|
|
<entry>expand an array to a set of rows</entry>
|
|
<entry><literal>unnest(ARRAY[1,2])</literal></entry>
|
|
<entry><literallayout class="monospaced">1
|
|
2</literallayout>(2 rows)</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
In <function>string_to_array</function>, if the delimiter parameter is
|
|
NULL, each character in the input string will become a separate element in
|
|
the resulting array. If the delimiter is an empty string, then the entire
|
|
input string is returned as a one-element array. Otherwise the input
|
|
string is split at each occurrence of the delimiter string.
|
|
</para>
|
|
|
|
<para>
|
|
In <function>string_to_array</function>, if the null-string parameter
|
|
is omitted or NULL, none of the substrings of the input will be replaced
|
|
by NULL.
|
|
In <function>array_to_string</function>, if the null-string parameter
|
|
is omitted or NULL, any null elements in the array are simply skipped
|
|
and not represented in the output string.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
There are two differences in the behavior of <function>string_to_array</>
|
|
from pre-9.1 versions of <productname>PostgreSQL</>.
|
|
First, it will return an empty (zero-element) array rather than NULL when
|
|
the input string is of zero length. Second, if the delimiter string is
|
|
NULL, the function splits the input into individual characters, rather
|
|
than returning NULL as before.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
See also <xref linkend="functions-aggregate"> about the aggregate
|
|
function <function>array_agg</function> for use with arrays.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="functions-aggregate">
|
|
<title>Aggregate Functions</title>
|
|
|
|
<indexterm zone="functions-aggregate">
|
|
<primary>aggregate function</primary>
|
|
<secondary>built-in</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<firstterm>Aggregate functions</firstterm> compute a single result
|
|
from a set of input values. The built-in aggregate functions
|
|
are listed in
|
|
<xref linkend="functions-aggregate-table"> and
|
|
<xref linkend="functions-aggregate-statistics-table">.
|
|
The special syntax considerations for aggregate
|
|
functions are explained in <xref linkend="syntax-aggregates">.
|
|
Consult <xref linkend="tutorial-agg"> for additional introductory
|
|
information.
|
|
</para>
|
|
|
|
<table id="functions-aggregate-table">
|
|
<title>General-Purpose Aggregate Functions</title>
|
|
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Argument Type(s)</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>array_agg</primary>
|
|
</indexterm>
|
|
<function>array_agg(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
any
|
|
</entry>
|
|
<entry>
|
|
array of the argument type
|
|
</entry>
|
|
<entry>input values, including nulls, concatenated into an array</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>average</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>avg</primary>
|
|
</indexterm>
|
|
<function>avg(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, <type>numeric</type>, or <type>interval</type>
|
|
</entry>
|
|
<entry>
|
|
<type>numeric</type> for any integer-type argument,
|
|
<type>double precision</type> for a floating-point argument,
|
|
otherwise the same as the argument data type
|
|
</entry>
|
|
<entry>the average (arithmetic mean) of all input values</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>bit_and</primary>
|
|
</indexterm>
|
|
<function>bit_and(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>, <type>bigint</type>, or
|
|
<type>bit</type>
|
|
</entry>
|
|
<entry>
|
|
same as argument data type
|
|
</entry>
|
|
<entry>the bitwise AND of all non-null input values, or null if none</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>bit_or</primary>
|
|
</indexterm>
|
|
<function>bit_or(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>, <type>bigint</type>, or
|
|
<type>bit</type>
|
|
</entry>
|
|
<entry>
|
|
same as argument data type
|
|
</entry>
|
|
<entry>the bitwise OR of all non-null input values, or null if none</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>bool_and</primary>
|
|
</indexterm>
|
|
<function>bool_and(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>true if all input values are true, otherwise false</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>bool_or</primary>
|
|
</indexterm>
|
|
<function>bool_or(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>true if at least one input value is true, otherwise false</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>count</primary>
|
|
</indexterm>
|
|
<function>count(*)</function>
|
|
</entry>
|
|
<entry></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>number of input rows</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><function>count(<replaceable class="parameter">expression</replaceable>)</function></entry>
|
|
<entry>any</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>
|
|
number of input rows for which the value of <replaceable
|
|
class="parameter">expression</replaceable> is not null
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>every</primary>
|
|
</indexterm>
|
|
<function>every(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bool</type>
|
|
</entry>
|
|
<entry>equivalent to <function>bool_and</function></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>max</primary>
|
|
</indexterm>
|
|
<function>max(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>any array, numeric, string, or date/time type</entry>
|
|
<entry>same as argument type</entry>
|
|
<entry>
|
|
maximum value of <replaceable
|
|
class="parameter">expression</replaceable> across all input
|
|
values
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>min</primary>
|
|
</indexterm>
|
|
<function>min(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>any array, numeric, string, or date/time type</entry>
|
|
<entry>same as argument type</entry>
|
|
<entry>
|
|
minimum value of <replaceable
|
|
class="parameter">expression</replaceable> across all input
|
|
values
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>string_agg</primary>
|
|
</indexterm>
|
|
<function>
|
|
string_agg(<replaceable class="parameter">expression</replaceable>,
|
|
<replaceable class="parameter">delimiter</replaceable>)
|
|
</function>
|
|
</entry>
|
|
<entry>
|
|
<type>text</type>, <type>text</type>
|
|
</entry>
|
|
<entry>
|
|
<type>text</type>
|
|
</entry>
|
|
<entry>input values concatenated into a string, separated by delimiter</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>sum</primary>
|
|
</indexterm>
|
|
<function>sum(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, <type>numeric</type>, or
|
|
<type>interval</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type> for <type>smallint</type> or
|
|
<type>int</type> arguments, <type>numeric</type> for
|
|
<type>bigint</type> arguments, <type>double precision</type>
|
|
for floating-point arguments, otherwise the same as the
|
|
argument data type
|
|
</entry>
|
|
<entry>sum of <replaceable class="parameter">expression</replaceable> across all input values</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>xmlagg</primary>
|
|
</indexterm>
|
|
<function>xmlagg(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>xml</type>
|
|
</entry>
|
|
<entry>
|
|
<type>xml</type>
|
|
</entry>
|
|
<entry>concatenation of XML values (see also <xref linkend="functions-xml-xmlagg">)</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
It should be noted that except for <function>count</function>,
|
|
these functions return a null value when no rows are selected. In
|
|
particular, <function>sum</function> of no rows returns null, not
|
|
zero as one might expect, and <function>array_agg</function>
|
|
returns null rather than an empty array when there are no input
|
|
rows. The <function>coalesce</function> function can be used to
|
|
substitute zero or an empty array for null when necessary.
|
|
</para>
|
|
|
|
<note>
|
|
<indexterm>
|
|
<primary>ANY</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>SOME</primary>
|
|
</indexterm>
|
|
<para>
|
|
Boolean aggregates <function>bool_and</function> and
|
|
<function>bool_or</function> correspond to standard SQL aggregates
|
|
<function>every</function> and <function>any</function> or
|
|
<function>some</function>.
|
|
As for <function>any</function> and <function>some</function>,
|
|
it seems that there is an ambiguity built into the standard syntax:
|
|
<programlisting>
|
|
SELECT b1 = ANY((SELECT b2 FROM t2 ...)) FROM t1 ...;
|
|
</programlisting>
|
|
Here <function>ANY</function> can be considered either as introducing
|
|
a subquery, or as being an aggregate function, if the subquery
|
|
returns one row with a Boolean value.
|
|
Thus the standard name cannot be given to these aggregates.
|
|
</para>
|
|
</note>
|
|
|
|
<note>
|
|
<para>
|
|
Users accustomed to working with other SQL database management
|
|
systems might be disappointed by the performance of the
|
|
<function>count</function> aggregate when it is applied to the
|
|
entire table. A query like:
|
|
<programlisting>
|
|
SELECT count(*) FROM sometable;
|
|
</programlisting>
|
|
will be executed by <productname>PostgreSQL</productname> using a
|
|
sequential scan of the entire table.
|
|
</para>
|
|
</note>
|
|
|
|
<para>
|
|
The aggregate functions <function>array_agg</function>,
|
|
<function>string_agg</function>,
|
|
and <function>xmlagg</function>, as well as similar user-defined
|
|
aggregate functions, produce meaningfully different result values
|
|
depending on the order of the input values. This ordering is
|
|
unspecified by default, but can be controlled by writing an
|
|
<literal>ORDER BY</> clause within the aggregate call, as shown in
|
|
<xref linkend="syntax-aggregates">.
|
|
Alternatively, supplying the input values from a sorted subquery
|
|
will usually work. For example:
|
|
|
|
<screen><![CDATA[
|
|
SELECT xmlagg(x) FROM (SELECT x FROM test ORDER BY y DESC) AS tab;
|
|
]]></screen>
|
|
|
|
But this syntax is not allowed in the SQL standard, and is
|
|
not portable to other database systems.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-aggregate-statistics-table"> shows
|
|
aggregate functions typically used in statistical analysis.
|
|
(These are separated out merely to avoid cluttering the listing
|
|
of more-commonly-used aggregates.) Where the description mentions
|
|
<replaceable class="parameter">N</replaceable>, it means the
|
|
number of input rows for which all the input expressions are non-null.
|
|
In all cases, null is returned if the computation is meaningless,
|
|
for example when <replaceable class="parameter">N</replaceable> is zero.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>statistics</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>linear regression</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-aggregate-statistics-table">
|
|
<title>Aggregate Functions for Statistics</title>
|
|
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Argument Type</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>correlation</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>corr</primary>
|
|
</indexterm>
|
|
<function>corr(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>correlation coefficient</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>covariance</primary>
|
|
<secondary>population</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>covar_pop</primary>
|
|
</indexterm>
|
|
<function>covar_pop(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>population covariance</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>covariance</primary>
|
|
<secondary>sample</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>covar_samp</primary>
|
|
</indexterm>
|
|
<function>covar_samp(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>sample covariance</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regr_avgx</primary>
|
|
</indexterm>
|
|
<function>regr_avgx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>average of the independent variable
|
|
(<literal>sum(<replaceable class="parameter">X</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regr_avgy</primary>
|
|
</indexterm>
|
|
<function>regr_avgy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>average of the dependent variable
|
|
(<literal>sum(<replaceable class="parameter">Y</replaceable>)/<replaceable class="parameter">N</replaceable></literal>)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regr_count</primary>
|
|
</indexterm>
|
|
<function>regr_count(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type>
|
|
</entry>
|
|
<entry>number of input rows in which both expressions are nonnull</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regression intercept</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>regr_intercept</primary>
|
|
</indexterm>
|
|
<function>regr_intercept(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>y-intercept of the least-squares-fit linear equation
|
|
determined by the (<replaceable
|
|
class="parameter">X</replaceable>, <replaceable
|
|
class="parameter">Y</replaceable>) pairs</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regr_r2</primary>
|
|
</indexterm>
|
|
<function>regr_r2(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>square of the correlation coefficient</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regression slope</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>regr_slope</primary>
|
|
</indexterm>
|
|
<function>regr_slope(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>slope of the least-squares-fit linear equation determined
|
|
by the (<replaceable class="parameter">X</replaceable>,
|
|
<replaceable class="parameter">Y</replaceable>) pairs</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regr_sxx</primary>
|
|
</indexterm>
|
|
<function>regr_sxx(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry><literal>sum(<replaceable
|
|
class="parameter">X</replaceable>^2) - sum(<replaceable
|
|
class="parameter">X</replaceable>)^2/<replaceable
|
|
class="parameter">N</replaceable></literal> (<quote>sum of
|
|
squares</quote> of the independent variable)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regr_sxy</primary>
|
|
</indexterm>
|
|
<function>regr_sxy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry><literal>sum(<replaceable
|
|
class="parameter">X</replaceable>*<replaceable
|
|
class="parameter">Y</replaceable>) - sum(<replaceable
|
|
class="parameter">X</replaceable>) * sum(<replaceable
|
|
class="parameter">Y</replaceable>)/<replaceable
|
|
class="parameter">N</replaceable></literal> (<quote>sum of
|
|
products</quote> of independent times dependent
|
|
variable)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>regr_syy</primary>
|
|
</indexterm>
|
|
<function>regr_syy(<replaceable class="parameter">Y</replaceable>, <replaceable class="parameter">X</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry><literal>sum(<replaceable
|
|
class="parameter">Y</replaceable>^2) - sum(<replaceable
|
|
class="parameter">Y</replaceable>)^2/<replaceable
|
|
class="parameter">N</replaceable></literal> (<quote>sum of
|
|
squares</quote> of the dependent variable)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>standard deviation</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>stddev</primary>
|
|
</indexterm>
|
|
<function>stddev(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, or <type>numeric</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> for floating-point arguments,
|
|
otherwise <type>numeric</type>
|
|
</entry>
|
|
<entry>historical alias for <function>stddev_samp</function></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>standard deviation</primary>
|
|
<secondary>population</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>stddev_pop</primary>
|
|
</indexterm>
|
|
<function>stddev_pop(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, or <type>numeric</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> for floating-point arguments,
|
|
otherwise <type>numeric</type>
|
|
</entry>
|
|
<entry>population standard deviation of the input values</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>standard deviation</primary>
|
|
<secondary>sample</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>stddev_samp</primary>
|
|
</indexterm>
|
|
<function>stddev_samp(<replaceable class="parameter">expression</replaceable>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, or <type>numeric</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> for floating-point arguments,
|
|
otherwise <type>numeric</type>
|
|
</entry>
|
|
<entry>sample standard deviation of the input values</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>variance</primary>
|
|
</indexterm>
|
|
<function>variance</function>(<replaceable class="parameter">expression</replaceable>)
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, or <type>numeric</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> for floating-point arguments,
|
|
otherwise <type>numeric</type>
|
|
</entry>
|
|
<entry>historical alias for <function>var_samp</function></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>variance</primary>
|
|
<secondary>population</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>var_pop</primary>
|
|
</indexterm>
|
|
<function>var_pop</function>(<replaceable class="parameter">expression</replaceable>)
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, or <type>numeric</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> for floating-point arguments,
|
|
otherwise <type>numeric</type>
|
|
</entry>
|
|
<entry>population variance of the input values (square of the population standard deviation)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>variance</primary>
|
|
<secondary>sample</secondary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>var_samp</primary>
|
|
</indexterm>
|
|
<function>var_samp</function>(<replaceable class="parameter">expression</replaceable>)
|
|
</entry>
|
|
<entry>
|
|
<type>smallint</type>, <type>int</type>,
|
|
<type>bigint</type>, <type>real</type>, <type>double
|
|
precision</type>, or <type>numeric</type>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type> for floating-point arguments,
|
|
otherwise <type>numeric</type>
|
|
</entry>
|
|
<entry>sample variance of the input values (square of the sample standard deviation)</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-window">
|
|
<title>Window Functions</title>
|
|
|
|
<indexterm zone="functions-window">
|
|
<primary>window function</primary>
|
|
<secondary>built-in</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<firstterm>Window functions</firstterm> provide the ability to perform
|
|
calculations across sets of rows that are related to the current query
|
|
row. See <xref linkend="tutorial-window"> for an introduction to this
|
|
feature.
|
|
</para>
|
|
|
|
<para>
|
|
The built-in window functions are listed in
|
|
<xref linkend="functions-window-table">. Note that these functions
|
|
<emphasis>must</> be invoked using window function syntax; that is an
|
|
<literal>OVER</> clause is required.
|
|
</para>
|
|
|
|
<para>
|
|
In addition to these functions, any built-in or user-defined aggregate
|
|
function can be used as a window function (see
|
|
<xref linkend="functions-aggregate"> for a list of the built-in aggregates).
|
|
Aggregate functions act as window functions only when an <literal>OVER</>
|
|
clause follows the call; otherwise they act as regular aggregates.
|
|
</para>
|
|
|
|
<table id="functions-window-table">
|
|
<title>General-Purpose Window Functions</title>
|
|
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>row_number</primary>
|
|
</indexterm>
|
|
<function>row_number()</function>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type>
|
|
</entry>
|
|
<entry>number of the current row within its partition, counting from 1</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>rank</primary>
|
|
</indexterm>
|
|
<function>rank()</function>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type>
|
|
</entry>
|
|
<entry>rank of the current row with gaps; same as <function>row_number</> of its first peer</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>dense_rank</primary>
|
|
</indexterm>
|
|
<function>dense_rank()</function>
|
|
</entry>
|
|
<entry>
|
|
<type>bigint</type>
|
|
</entry>
|
|
<entry>rank of the current row without gaps; this function counts peer groups</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>percent_rank</primary>
|
|
</indexterm>
|
|
<function>percent_rank()</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>relative rank of the current row: (<function>rank</> - 1) / (total rows - 1)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>cume_dist</primary>
|
|
</indexterm>
|
|
<function>cume_dist()</function>
|
|
</entry>
|
|
<entry>
|
|
<type>double precision</type>
|
|
</entry>
|
|
<entry>relative rank of the current row: (number of rows preceding or peer with current row) / (total rows)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>ntile</primary>
|
|
</indexterm>
|
|
<function>ntile(<replaceable class="parameter">num_buckets</replaceable> <type>integer</>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>integer</type>
|
|
</entry>
|
|
<entry>integer ranging from 1 to the argument value, dividing the
|
|
partition as equally as possible</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>lag</primary>
|
|
</indexterm>
|
|
<function>
|
|
lag(<replaceable class="parameter">value</replaceable> <type>any</>
|
|
[, <replaceable class="parameter">offset</replaceable> <type>integer</>
|
|
[, <replaceable class="parameter">default</replaceable> <type>any</> ]])
|
|
</function>
|
|
</entry>
|
|
<entry>
|
|
<type>same type as <replaceable class="parameter">value</replaceable></type>
|
|
</entry>
|
|
<entry>
|
|
returns <replaceable class="parameter">value</replaceable> evaluated at
|
|
the row that is <replaceable class="parameter">offset</replaceable>
|
|
rows before the current row within the partition; if there is no such
|
|
row, instead return <replaceable class="parameter">default</replaceable>.
|
|
Both <replaceable class="parameter">offset</replaceable> and
|
|
<replaceable class="parameter">default</replaceable> are evaluated
|
|
with respect to the current row. If omitted,
|
|
<replaceable class="parameter">offset</replaceable> defaults to 1 and
|
|
<replaceable class="parameter">default</replaceable> to null
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>lead</primary>
|
|
</indexterm>
|
|
<function>
|
|
lead(<replaceable class="parameter">value</replaceable> <type>any</>
|
|
[, <replaceable class="parameter">offset</replaceable> <type>integer</>
|
|
[, <replaceable class="parameter">default</replaceable> <type>any</> ]])
|
|
</function>
|
|
</entry>
|
|
<entry>
|
|
<type>same type as <replaceable class="parameter">value</replaceable></type>
|
|
</entry>
|
|
<entry>
|
|
returns <replaceable class="parameter">value</replaceable> evaluated at
|
|
the row that is <replaceable class="parameter">offset</replaceable>
|
|
rows after the current row within the partition; if there is no such
|
|
row, instead return <replaceable class="parameter">default</replaceable>.
|
|
Both <replaceable class="parameter">offset</replaceable> and
|
|
<replaceable class="parameter">default</replaceable> are evaluated
|
|
with respect to the current row. If omitted,
|
|
<replaceable class="parameter">offset</replaceable> defaults to 1 and
|
|
<replaceable class="parameter">default</replaceable> to null
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>first_value</primary>
|
|
</indexterm>
|
|
<function>first_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>same type as <replaceable class="parameter">value</replaceable></type>
|
|
</entry>
|
|
<entry>
|
|
returns <replaceable class="parameter">value</replaceable> evaluated
|
|
at the row that is the first row of the window frame
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>last_value</primary>
|
|
</indexterm>
|
|
<function>last_value(<replaceable class="parameter">value</replaceable> <type>any</>)</function>
|
|
</entry>
|
|
<entry>
|
|
<type>same type as <replaceable class="parameter">value</replaceable></type>
|
|
</entry>
|
|
<entry>
|
|
returns <replaceable class="parameter">value</replaceable> evaluated
|
|
at the row that is the last row of the window frame
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>nth_value</primary>
|
|
</indexterm>
|
|
<function>
|
|
nth_value(<replaceable class="parameter">value</replaceable> <type>any</>, <replaceable class="parameter">nth</replaceable> <type>integer</>)
|
|
</function>
|
|
</entry>
|
|
<entry>
|
|
<type>same type as <replaceable class="parameter">value</replaceable></type>
|
|
</entry>
|
|
<entry>
|
|
returns <replaceable class="parameter">value</replaceable> evaluated
|
|
at the row that is the <replaceable class="parameter">nth</replaceable>
|
|
row of the window frame (counting from 1); null if no such row
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
All of the functions listed in
|
|
<xref linkend="functions-window-table"> depend on the sort ordering
|
|
specified by the <literal>ORDER BY</> clause of the associated window
|
|
definition. Rows that are not distinct in the <literal>ORDER BY</>
|
|
ordering are said to be <firstterm>peers</>; the four ranking functions
|
|
are defined so that they give the same answer for any two peer rows.
|
|
</para>
|
|
|
|
<para>
|
|
Note that <function>first_value</>, <function>last_value</>, and
|
|
<function>nth_value</> consider only the rows within the <quote>window
|
|
frame</>, which by default contains the rows from the start of the
|
|
partition through the last peer of the current row. This is
|
|
likely to give unhelpful results for <function>last_value</> and
|
|
sometimes also <function>nth_value</>. You can redefine the frame by
|
|
adding a suitable frame specification (<literal>RANGE</> or
|
|
<literal>ROWS</>) to the <literal>OVER</> clause.
|
|
See <xref linkend="syntax-window-functions"> for more information
|
|
about frame specifications.
|
|
</para>
|
|
|
|
<para>
|
|
When an aggregate function is used as a window function, it aggregates
|
|
over the rows within the current row's window frame.
|
|
An aggregate used with <literal>ORDER BY</> and the default window frame
|
|
definition produces a <quote>running sum</> type of behavior, which may or
|
|
may not be what's wanted. To obtain
|
|
aggregation over the whole partition, omit <literal>ORDER BY</> or use
|
|
<literal>ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING</>.
|
|
Other frame specifications can be used to obtain other effects.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The SQL standard defines a <literal>RESPECT NULLS</> or
|
|
<literal>IGNORE NULLS</> option for <function>lead</>, <function>lag</>,
|
|
<function>first_value</>, <function>last_value</>, and
|
|
<function>nth_value</>. This is not implemented in
|
|
<productname>PostgreSQL</productname>: the behavior is always the
|
|
same as the standard's default, namely <literal>RESPECT NULLS</>.
|
|
Likewise, the standard's <literal>FROM FIRST</> or <literal>FROM LAST</>
|
|
option for <function>nth_value</> is not implemented: only the
|
|
default <literal>FROM FIRST</> behavior is supported. (You can achieve
|
|
the result of <literal>FROM LAST</> by reversing the <literal>ORDER BY</>
|
|
ordering.)
|
|
</para>
|
|
</note>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-subquery">
|
|
<title>Subquery Expressions</title>
|
|
|
|
<indexterm>
|
|
<primary>EXISTS</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>IN</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>NOT IN</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>ANY</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>ALL</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>SOME</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>subquery</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes the <acronym>SQL</acronym>-compliant subquery
|
|
expressions available in <productname>PostgreSQL</productname>.
|
|
All of the expression forms documented in this section return
|
|
Boolean (true/false) results.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title><literal>EXISTS</literal></title>
|
|
|
|
<synopsis>
|
|
EXISTS (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The argument of <token>EXISTS</token> is an arbitrary <command>SELECT</> statement,
|
|
or <firstterm>subquery</firstterm>. The
|
|
subquery is evaluated to determine whether it returns any rows.
|
|
If it returns at least one row, the result of <token>EXISTS</token> is
|
|
<quote>true</>; if the subquery returns no rows, the result of <token>EXISTS</token>
|
|
is <quote>false</>.
|
|
</para>
|
|
|
|
<para>
|
|
The subquery can refer to variables from the surrounding query,
|
|
which will act as constants during any one evaluation of the subquery.
|
|
</para>
|
|
|
|
<para>
|
|
The subquery will generally only be executed long enough to determine
|
|
whether at least one row is returned, not all the way to completion.
|
|
It is unwise to write a subquery that has side effects (such as
|
|
calling sequence functions); whether the side effects occur
|
|
might be unpredictable.
|
|
</para>
|
|
|
|
<para>
|
|
Since the result depends only on whether any rows are returned,
|
|
and not on the contents of those rows, the output list of the
|
|
subquery is normally unimportant. A common coding convention is
|
|
to write all <literal>EXISTS</> tests in the form
|
|
<literal>EXISTS(SELECT 1 WHERE ...)</literal>. There are exceptions to
|
|
this rule however, such as subqueries that use <token>INTERSECT</token>.
|
|
</para>
|
|
|
|
<para>
|
|
This simple example is like an inner join on <literal>col2</>, but
|
|
it produces at most one output row for each <literal>tab1</> row,
|
|
even if there are several matching <literal>tab2</> rows:
|
|
<screen>
|
|
SELECT col1
|
|
FROM tab1
|
|
WHERE EXISTS (SELECT 1 FROM tab2 WHERE col2 = tab1.col2);
|
|
</screen>
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>IN</literal></title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> IN (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly one column. The left-hand expression
|
|
is evaluated and compared to each row of the subquery result.
|
|
The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
|
|
The result is <quote>false</> if no equal row is found (including the
|
|
case where the subquery returns no rows).
|
|
</para>
|
|
|
|
<para>
|
|
Note that if the left-hand expression yields null, or if there are
|
|
no equal right-hand values and at least one right-hand row yields
|
|
null, the result of the <token>IN</token> construct will be null, not false.
|
|
This is in accordance with SQL's normal rules for Boolean combinations
|
|
of null values.
|
|
</para>
|
|
|
|
<para>
|
|
As with <token>EXISTS</token>, it's unwise to assume that the subquery will
|
|
be evaluated completely.
|
|
</para>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> IN (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The left-hand side of this form of <token>IN</token> is a row constructor,
|
|
as described in <xref linkend="sql-syntax-row-constructors">.
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly as many columns as there are
|
|
expressions in the left-hand row. The left-hand expressions are
|
|
evaluated and compared row-wise to each row of the subquery result.
|
|
The result of <token>IN</token> is <quote>true</> if any equal subquery row is found.
|
|
The result is <quote>false</> if no equal row is found (including the
|
|
case where the subquery returns no rows).
|
|
</para>
|
|
|
|
<para>
|
|
As usual, null values in the rows are combined per
|
|
the normal rules of SQL Boolean expressions. Two rows are considered
|
|
equal if all their corresponding members are non-null and equal; the rows
|
|
are unequal if any corresponding members are non-null and unequal;
|
|
otherwise the result of that row comparison is unknown (null).
|
|
If all the per-row results are either unequal or null, with at least one
|
|
null, then the result of <token>IN</token> is null.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>NOT IN</literal></title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> NOT IN (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly one column. The left-hand expression
|
|
is evaluated and compared to each row of the subquery result.
|
|
The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
|
|
are found (including the case where the subquery returns no rows).
|
|
The result is <quote>false</> if any equal row is found.
|
|
</para>
|
|
|
|
<para>
|
|
Note that if the left-hand expression yields null, or if there are
|
|
no equal right-hand values and at least one right-hand row yields
|
|
null, the result of the <token>NOT IN</token> construct will be null, not true.
|
|
This is in accordance with SQL's normal rules for Boolean combinations
|
|
of null values.
|
|
</para>
|
|
|
|
<para>
|
|
As with <token>EXISTS</token>, it's unwise to assume that the subquery will
|
|
be evaluated completely.
|
|
</para>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> NOT IN (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The left-hand side of this form of <token>NOT IN</token> is a row constructor,
|
|
as described in <xref linkend="sql-syntax-row-constructors">.
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly as many columns as there are
|
|
expressions in the left-hand row. The left-hand expressions are
|
|
evaluated and compared row-wise to each row of the subquery result.
|
|
The result of <token>NOT IN</token> is <quote>true</> if only unequal subquery rows
|
|
are found (including the case where the subquery returns no rows).
|
|
The result is <quote>false</> if any equal row is found.
|
|
</para>
|
|
|
|
<para>
|
|
As usual, null values in the rows are combined per
|
|
the normal rules of SQL Boolean expressions. Two rows are considered
|
|
equal if all their corresponding members are non-null and equal; the rows
|
|
are unequal if any corresponding members are non-null and unequal;
|
|
otherwise the result of that row comparison is unknown (null).
|
|
If all the per-row results are either unequal or null, with at least one
|
|
null, then the result of <token>NOT IN</token> is null.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>ANY</literal>/<literal>SOME</literal></title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>subquery</replaceable>)
|
|
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly one column. The left-hand expression
|
|
is evaluated and compared to each row of the subquery result using the
|
|
given <replaceable>operator</replaceable>, which must yield a Boolean
|
|
result.
|
|
The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
|
|
The result is <quote>false</> if no true result is found (including the
|
|
case where the subquery returns no rows).
|
|
</para>
|
|
|
|
<para>
|
|
<token>SOME</token> is a synonym for <token>ANY</token>.
|
|
<token>IN</token> is equivalent to <literal>= ANY</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
Note that if there are no successes and at least one right-hand row yields
|
|
null for the operator's result, the result of the <token>ANY</token> construct
|
|
will be null, not false.
|
|
This is in accordance with SQL's normal rules for Boolean combinations
|
|
of null values.
|
|
</para>
|
|
|
|
<para>
|
|
As with <token>EXISTS</token>, it's unwise to assume that the subquery will
|
|
be evaluated completely.
|
|
</para>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> <replaceable>operator</> ANY (<replaceable>subquery</replaceable>)
|
|
<replaceable>row_constructor</replaceable> <replaceable>operator</> SOME (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The left-hand side of this form of <token>ANY</token> is a row constructor,
|
|
as described in <xref linkend="sql-syntax-row-constructors">.
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly as many columns as there are
|
|
expressions in the left-hand row. The left-hand expressions are
|
|
evaluated and compared row-wise to each row of the subquery result,
|
|
using the given <replaceable>operator</replaceable>.
|
|
The result of <token>ANY</token> is <quote>true</> if the comparison
|
|
returns true for any subquery row.
|
|
The result is <quote>false</> if the comparison returns false for every
|
|
subquery row (including the case where the subquery returns no
|
|
rows).
|
|
The result is NULL if the comparison does not return true for any row,
|
|
and it returns NULL for at least one row.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="row-wise-comparison"> for details about the meaning
|
|
of a row-wise comparison.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>ALL</literal></title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly one column. The left-hand expression
|
|
is evaluated and compared to each row of the subquery result using the
|
|
given <replaceable>operator</replaceable>, which must yield a Boolean
|
|
result.
|
|
The result of <token>ALL</token> is <quote>true</> if all rows yield true
|
|
(including the case where the subquery returns no rows).
|
|
The result is <quote>false</> if any false result is found.
|
|
The result is NULL if the comparison does not return false for any row,
|
|
and it returns NULL for at least one row.
|
|
</para>
|
|
|
|
<para>
|
|
<token>NOT IN</token> is equivalent to <literal><> ALL</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
As with <token>EXISTS</token>, it's unwise to assume that the subquery will
|
|
be evaluated completely.
|
|
</para>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The left-hand side of this form of <token>ALL</token> is a row constructor,
|
|
as described in <xref linkend="sql-syntax-row-constructors">.
|
|
The right-hand side is a parenthesized
|
|
subquery, which must return exactly as many columns as there are
|
|
expressions in the left-hand row. The left-hand expressions are
|
|
evaluated and compared row-wise to each row of the subquery result,
|
|
using the given <replaceable>operator</replaceable>.
|
|
The result of <token>ALL</token> is <quote>true</> if the comparison
|
|
returns true for all subquery rows (including the
|
|
case where the subquery returns no rows).
|
|
The result is <quote>false</> if the comparison returns false for any
|
|
subquery row.
|
|
The result is NULL if the comparison does not return false for any
|
|
subquery row, and it returns NULL for at least one row.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="row-wise-comparison"> for details about the meaning
|
|
of a row-wise comparison.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title>Row-wise Comparison</title>
|
|
|
|
<indexterm zone="functions-subquery">
|
|
<primary>comparison</primary>
|
|
<secondary>subquery result row</secondary>
|
|
</indexterm>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> (<replaceable>subquery</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The left-hand side is a row constructor,
|
|
as described in <xref linkend="sql-syntax-row-constructors">.
|
|
The right-hand side is a parenthesized subquery, which must return exactly
|
|
as many columns as there are expressions in the left-hand row. Furthermore,
|
|
the subquery cannot return more than one row. (If it returns zero rows,
|
|
the result is taken to be null.) The left-hand side is evaluated and
|
|
compared row-wise to the single subquery result row.
|
|
</para>
|
|
|
|
<para>
|
|
See <xref linkend="row-wise-comparison"> for details about the meaning
|
|
of a row-wise comparison.
|
|
</para>
|
|
</sect2>
|
|
</sect1>
|
|
|
|
|
|
<sect1 id="functions-comparisons">
|
|
<title>Row and Array Comparisons</title>
|
|
|
|
<indexterm>
|
|
<primary>IN</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>NOT IN</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>ANY</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>ALL</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>SOME</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>row-wise comparison</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>comparison</primary>
|
|
<secondary>row-wise</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>IS DISTINCT FROM</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>IS NOT DISTINCT FROM</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes several specialized constructs for making
|
|
multiple comparisons between groups of values. These forms are
|
|
syntactically related to the subquery forms of the previous section,
|
|
but do not involve subqueries.
|
|
The forms involving array subexpressions are
|
|
<productname>PostgreSQL</productname> extensions; the rest are
|
|
<acronym>SQL</acronym>-compliant.
|
|
All of the expression forms documented in this section return
|
|
Boolean (true/false) results.
|
|
</para>
|
|
|
|
<sect2>
|
|
<title><literal>IN</literal></title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> IN (<replaceable>value</replaceable> <optional>, ...</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized list
|
|
of scalar expressions. The result is <quote>true</> if the left-hand expression's
|
|
result is equal to any of the right-hand expressions. This is a shorthand
|
|
notation for
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> = <replaceable>value1</replaceable>
|
|
OR
|
|
<replaceable>expression</replaceable> = <replaceable>value2</replaceable>
|
|
OR
|
|
...
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
Note that if the left-hand expression yields null, or if there are
|
|
no equal right-hand values and at least one right-hand expression yields
|
|
null, the result of the <token>IN</token> construct will be null, not false.
|
|
This is in accordance with SQL's normal rules for Boolean combinations
|
|
of null values.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>NOT IN</literal></title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> NOT IN (<replaceable>value</replaceable> <optional>, ...</optional>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized list
|
|
of scalar expressions. The result is <quote>true</quote> if the left-hand expression's
|
|
result is unequal to all of the right-hand expressions. This is a shorthand
|
|
notation for
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> <> <replaceable>value1</replaceable>
|
|
AND
|
|
<replaceable>expression</replaceable> <> <replaceable>value2</replaceable>
|
|
AND
|
|
...
|
|
</synopsis>
|
|
</para>
|
|
|
|
<para>
|
|
Note that if the left-hand expression yields null, or if there are
|
|
no equal right-hand values and at least one right-hand expression yields
|
|
null, the result of the <token>NOT IN</token> construct will be null, not true
|
|
as one might naively expect.
|
|
This is in accordance with SQL's normal rules for Boolean combinations
|
|
of null values.
|
|
</para>
|
|
|
|
<tip>
|
|
<para>
|
|
<literal>x NOT IN y</literal> is equivalent to <literal>NOT (x IN y)</literal> in all
|
|
cases. However, null values are much more likely to trip up the novice when
|
|
working with <token>NOT IN</token> than when working with <token>IN</token>.
|
|
It is best to express your condition positively if possible.
|
|
</para>
|
|
</tip>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>ANY</literal>/<literal>SOME</literal> (array)</title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ANY (<replaceable>array expression</replaceable>)
|
|
<replaceable>expression</replaceable> <replaceable>operator</replaceable> SOME (<replaceable>array expression</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized expression, which must yield an
|
|
array value.
|
|
The left-hand expression
|
|
is evaluated and compared to each element of the array using the
|
|
given <replaceable>operator</replaceable>, which must yield a Boolean
|
|
result.
|
|
The result of <token>ANY</token> is <quote>true</> if any true result is obtained.
|
|
The result is <quote>false</> if no true result is found (including the
|
|
case where the array has zero elements).
|
|
</para>
|
|
|
|
<para>
|
|
If the array expression yields a null array, the result of
|
|
<token>ANY</token> will be null. If the left-hand expression yields null,
|
|
the result of <token>ANY</token> is ordinarily null (though a non-strict
|
|
comparison operator could possibly yield a different result).
|
|
Also, if the right-hand array contains any null elements and no true
|
|
comparison result is obtained, the result of <token>ANY</token>
|
|
will be null, not false (again, assuming a strict comparison operator).
|
|
This is in accordance with SQL's normal rules for Boolean combinations
|
|
of null values.
|
|
</para>
|
|
|
|
<para>
|
|
<token>SOME</token> is a synonym for <token>ANY</token>.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2>
|
|
<title><literal>ALL</literal> (array)</title>
|
|
|
|
<synopsis>
|
|
<replaceable>expression</replaceable> <replaceable>operator</replaceable> ALL (<replaceable>array expression</replaceable>)
|
|
</synopsis>
|
|
|
|
<para>
|
|
The right-hand side is a parenthesized expression, which must yield an
|
|
array value.
|
|
The left-hand expression
|
|
is evaluated and compared to each element of the array using the
|
|
given <replaceable>operator</replaceable>, which must yield a Boolean
|
|
result.
|
|
The result of <token>ALL</token> is <quote>true</> if all comparisons yield true
|
|
(including the case where the array has zero elements).
|
|
The result is <quote>false</> if any false result is found.
|
|
</para>
|
|
|
|
<para>
|
|
If the array expression yields a null array, the result of
|
|
<token>ALL</token> will be null. If the left-hand expression yields null,
|
|
the result of <token>ALL</token> is ordinarily null (though a non-strict
|
|
comparison operator could possibly yield a different result).
|
|
Also, if the right-hand array contains any null elements and no false
|
|
comparison result is obtained, the result of <token>ALL</token>
|
|
will be null, not true (again, assuming a strict comparison operator).
|
|
This is in accordance with SQL's normal rules for Boolean combinations
|
|
of null values.
|
|
</para>
|
|
</sect2>
|
|
|
|
<sect2 id="row-wise-comparison">
|
|
<title>Row-wise Comparison</title>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> <replaceable>operator</replaceable> <replaceable>row_constructor</replaceable>
|
|
</synopsis>
|
|
|
|
<para>
|
|
Each side is a row constructor,
|
|
as described in <xref linkend="sql-syntax-row-constructors">.
|
|
The two row values must have the same number of fields.
|
|
Each side is evaluated and they are compared row-wise. Row comparisons
|
|
are allowed when the <replaceable>operator</replaceable> is
|
|
<literal>=</>,
|
|
<literal><></>,
|
|
<literal><</>,
|
|
<literal><=</>,
|
|
<literal>></> or
|
|
<literal>>=</>,
|
|
or has semantics similar to one of these. (To be specific, an operator
|
|
can be a row comparison operator if it is a member of a B-tree operator
|
|
class, or is the negator of the <literal>=</> member of a B-tree operator
|
|
class.)
|
|
</para>
|
|
|
|
<para>
|
|
The <literal>=</> and <literal><></> cases work slightly differently
|
|
from the others. Two rows are considered
|
|
equal if all their corresponding members are non-null and equal; the rows
|
|
are unequal if any corresponding members are non-null and unequal;
|
|
otherwise the result of the row comparison is unknown (null).
|
|
</para>
|
|
|
|
<para>
|
|
For the <literal><</>, <literal><=</>, <literal>></> and
|
|
<literal>>=</> cases, the row elements are compared left-to-right,
|
|
stopping as soon as an unequal or null pair of elements is found.
|
|
If either of this pair of elements is null, the result of the
|
|
row comparison is unknown (null); otherwise comparison of this pair
|
|
of elements determines the result. For example,
|
|
<literal>ROW(1,2,NULL) < ROW(1,3,0)</>
|
|
yields true, not null, because the third pair of elements are not
|
|
considered.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
Prior to <productname>PostgreSQL</productname> 8.2, the
|
|
<literal><</>, <literal><=</>, <literal>></> and <literal>>=</>
|
|
cases were not handled per SQL specification. A comparison like
|
|
<literal>ROW(a,b) < ROW(c,d)</>
|
|
was implemented as
|
|
<literal>a < c AND b < d</>
|
|
whereas the correct behavior is equivalent to
|
|
<literal>a < c OR (a = c AND b < d)</>.
|
|
</para>
|
|
</note>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> IS DISTINCT FROM <replaceable>row_constructor</replaceable>
|
|
</synopsis>
|
|
|
|
<para>
|
|
This construct is similar to a <literal><></literal> row comparison,
|
|
but it does not yield null for null inputs. Instead, any null value is
|
|
considered unequal to (distinct from) any non-null value, and any two
|
|
nulls are considered equal (not distinct). Thus the result will
|
|
either be true or false, never null.
|
|
</para>
|
|
|
|
<synopsis>
|
|
<replaceable>row_constructor</replaceable> IS NOT DISTINCT FROM <replaceable>row_constructor</replaceable>
|
|
</synopsis>
|
|
|
|
<para>
|
|
This construct is similar to a <literal>=</literal> row comparison,
|
|
but it does not yield null for null inputs. Instead, any null value is
|
|
considered unequal to (distinct from) any non-null value, and any two
|
|
nulls are considered equal (not distinct). Thus the result will always
|
|
be either true or false, never null.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The SQL specification requires row-wise comparison to return NULL if the
|
|
result depends on comparing two NULL values or a NULL and a non-NULL.
|
|
<productname>PostgreSQL</productname> does this only when comparing the
|
|
results of two row constructors or comparing a row constructor to the
|
|
output of a subquery (as in <xref linkend="functions-subquery">).
|
|
In other contexts where two composite-type values are compared, two
|
|
NULL field values are considered equal, and a NULL is considered larger
|
|
than a non-NULL. This is necessary in order to have consistent sorting
|
|
and indexing behavior for composite types.
|
|
</para>
|
|
</note>
|
|
|
|
</sect2>
|
|
</sect1>
|
|
|
|
<sect1 id="functions-srf">
|
|
<title>Set Returning Functions</title>
|
|
|
|
<indexterm zone="functions-srf">
|
|
<primary>set returning functions</primary>
|
|
<secondary>functions</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>generate_series</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
This section describes functions that possibly return more than one row.
|
|
Currently the only functions in this class are series generating functions,
|
|
as detailed in <xref linkend="functions-srf-series"> and
|
|
<xref linkend="functions-srf-subscripts">.
|
|
</para>
|
|
|
|
<table id="functions-srf-series">
|
|
<title>Series Generating Functions</title>
|
|
<tgroup cols="4">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Argument Type</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>)</function></literal></entry>
|
|
<entry><type>int</type> or <type>bigint</type></entry>
|
|
<entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
|
|
<entry>
|
|
Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
|
|
with a step size of one
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter>)</function></literal></entry>
|
|
<entry><type>int</type> or <type>bigint</type></entry>
|
|
<entry><type>setof int</type> or <type>setof bigint</type> (same as argument type)</entry>
|
|
<entry>
|
|
Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
|
|
with a step size of <parameter>step</parameter>
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>generate_series(<parameter>start</parameter>, <parameter>stop</parameter>, <parameter>step</parameter> <type>interval</>)</function></literal></entry>
|
|
<entry><type>timestamp</type> or <type>timestamp with time zone</type></entry>
|
|
<entry><type>setof timestamp</type> or <type>setof timestamp with time zone</type> (same as argument type)</entry>
|
|
<entry>
|
|
Generate a series of values, from <parameter>start</parameter> to <parameter>stop</parameter>
|
|
with a step size of <parameter>step</parameter>
|
|
</entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
When <parameter>step</parameter> is positive, zero rows are returned if
|
|
<parameter>start</parameter> is greater than <parameter>stop</parameter>.
|
|
Conversely, when <parameter>step</parameter> is negative, zero rows are
|
|
returned if <parameter>start</parameter> is less than <parameter>stop</parameter>.
|
|
Zero rows are also returned for <literal>NULL</literal> inputs. It is an error
|
|
for <parameter>step</parameter> to be zero. Some examples follow:
|
|
<programlisting>
|
|
SELECT * FROM generate_series(2,4);
|
|
generate_series
|
|
-----------------
|
|
2
|
|
3
|
|
4
|
|
(3 rows)
|
|
|
|
SELECT * FROM generate_series(5,1,-2);
|
|
generate_series
|
|
-----------------
|
|
5
|
|
3
|
|
1
|
|
(3 rows)
|
|
|
|
SELECT * FROM generate_series(4,3);
|
|
generate_series
|
|
-----------------
|
|
(0 rows)
|
|
|
|
-- this example relies on the date-plus-integer operator
|
|
SELECT current_date + s.a AS dates FROM generate_series(0,14,7) AS s(a);
|
|
dates
|
|
------------
|
|
2004-02-05
|
|
2004-02-12
|
|
2004-02-19
|
|
(3 rows)
|
|
|
|
SELECT * FROM generate_series('2008-03-01 00:00'::timestamp,
|
|
'2008-03-04 12:00', '10 hours');
|
|
generate_series
|
|
---------------------
|
|
2008-03-01 00:00:00
|
|
2008-03-01 10:00:00
|
|
2008-03-01 20:00:00
|
|
2008-03-02 06:00:00
|
|
2008-03-02 16:00:00
|
|
2008-03-03 02:00:00
|
|
2008-03-03 12:00:00
|
|
2008-03-03 22:00:00
|
|
2008-03-04 08:00:00
|
|
(9 rows)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<table id="functions-srf-subscripts">
|
|
<title>Subscript Generating Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row>
|
|
<entry>Function</entry>
|
|
<entry>Return Type</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>)</function></literal></entry>
|
|
<entry><type>setof int</type></entry>
|
|
<entry>
|
|
Generate a series comprising the given array's subscripts.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>generate_subscripts(<parameter>array anyarray</parameter>, <parameter>dim int</parameter>, <parameter>reverse boolean</parameter>)</function></literal></entry>
|
|
<entry><type>setof int</type></entry>
|
|
<entry>
|
|
Generate a series comprising the given array's subscripts. When
|
|
<parameter>reverse</parameter> is true, the series is returned in
|
|
reverse order.
|
|
</entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<indexterm>
|
|
<primary>generate_subscripts</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>generate_subscripts</> is a convenience function that generates
|
|
the set of valid subscripts for the specified dimension of the given
|
|
array.
|
|
Zero rows are returned for arrays that do not have the requested dimension,
|
|
or for NULL arrays (but valid subscripts are returned for NULL array
|
|
elements). Some examples follow:
|
|
<programlisting>
|
|
-- basic usage
|
|
SELECT generate_subscripts('{NULL,1,NULL,2}'::int[], 1) AS s;
|
|
s
|
|
---
|
|
1
|
|
2
|
|
3
|
|
4
|
|
(4 rows)
|
|
|
|
-- presenting an array, the subscript and the subscripted
|
|
-- value requires a subquery
|
|
SELECT * FROM arrays;
|
|
a
|
|
--------------------
|
|
{-1,-2}
|
|
{100,200,300}
|
|
(2 rows)
|
|
|
|
SELECT a AS array, s AS subscript, a[s] AS value
|
|
FROM (SELECT generate_subscripts(a, 1) AS s, a FROM arrays) foo;
|
|
array | subscript | value
|
|
---------------+-----------+-------
|
|
{-1,-2} | 1 | -1
|
|
{-1,-2} | 2 | -2
|
|
{100,200,300} | 1 | 100
|
|
{100,200,300} | 2 | 200
|
|
{100,200,300} | 3 | 300
|
|
(5 rows)
|
|
|
|
-- unnest a 2D array
|
|
CREATE OR REPLACE FUNCTION unnest2(anyarray)
|
|
RETURNS SETOF anyelement AS $$
|
|
select $1[i][j]
|
|
from generate_subscripts($1,1) g1(i),
|
|
generate_subscripts($1,2) g2(j);
|
|
$$ LANGUAGE sql IMMUTABLE;
|
|
CREATE FUNCTION
|
|
postgres=# SELECT * FROM unnest2(ARRAY[[1,2],[3,4]]);
|
|
unnest2
|
|
---------
|
|
1
|
|
2
|
|
3
|
|
4
|
|
(4 rows)
|
|
</programlisting>
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-info">
|
|
<title>System Information Functions</title>
|
|
|
|
<para>
|
|
<xref linkend="functions-info-session-table"> shows several
|
|
functions that extract session and system information.
|
|
</para>
|
|
|
|
<para>
|
|
In addition to the functions listed in this section, there are a number of
|
|
functions related to the statistics system that also provide system
|
|
information. See <xref linkend="monitoring-stats-views"> for more
|
|
information.
|
|
</para>
|
|
|
|
<table id="functions-info-session-table">
|
|
<title>Session Information Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>current_catalog</function></literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>name of current database (called <quote>catalog</quote> in the SQL standard)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>current_database()</function></literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>name of current database</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>current_query()</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>text of the currently executing query, as submitted
|
|
by the client (might contain more than one statement)</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>current_schema</function>[()]</literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>name of current schema</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>current_schemas(<type>boolean</type>)</function></literal></entry>
|
|
<entry><type>name[]</type></entry>
|
|
<entry>names of schemas in search path, optionally including implicit schemas</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>current_user</function></literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>user name of current execution context</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>inet_client_addr()</function></literal></entry>
|
|
<entry><type>inet</type></entry>
|
|
<entry>address of the remote connection</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>inet_client_port()</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>port of the remote connection</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>inet_server_addr()</function></literal></entry>
|
|
<entry><type>inet</type></entry>
|
|
<entry>address of the local connection</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>inet_server_port()</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>port of the local connection</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<!-- See also the entry for this in monitoring.sgml -->
|
|
<entry><literal><function>pg_backend_pid()</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>
|
|
Process ID of the server process attached to the current session
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>pg_conf_load_time()</function></literal></entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>configuration load time</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>pg_is_other_temp_schema(<type>oid</type>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is schema another session's temporary schema?</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>pg_listening_channels()</function></literal></entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>channel names that the session is currently listening on</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>pg_my_temp_schema()</function></literal></entry>
|
|
<entry><type>oid</type></entry>
|
|
<entry>OID of session's temporary schema, or 0 if none</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>pg_postmaster_start_time()</function></literal></entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>server start time</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>session_user</function></literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>session user name</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>user</function></literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>equivalent to <function>current_user</function></entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><literal><function>version()</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry><productname>PostgreSQL</> version information</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<note>
|
|
<para>
|
|
<function>current_catalog</function>, <function>current_schema</function>,
|
|
<function>current_user</function>, <function>session_user</function>,
|
|
and <function>user</function> have special syntactic status
|
|
in <acronym>SQL</acronym>: they must be called without trailing
|
|
parentheses. (In PostgreSQL, parentheses can optionally be used with
|
|
<function>current_schema</function>, but not with the others.)
|
|
</para>
|
|
</note>
|
|
|
|
<indexterm>
|
|
<primary>current_catalog</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>current_database</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>current_query</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>current_schema</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>current_schemas</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>current_user</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_backend_pid</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>schema</primary>
|
|
<secondary>current</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>search path</primary>
|
|
<secondary>current</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>session_user</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>user</primary>
|
|
<secondary>current</secondary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>user</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The <function>session_user</function> is normally the user who initiated
|
|
the current database connection; but superusers can change this setting
|
|
with <xref linkend="sql-set-session-authorization">.
|
|
The <function>current_user</function> is the user identifier
|
|
that is applicable for permission checking. Normally it is equal
|
|
to the session user, but it can be changed with
|
|
<xref linkend="sql-set-role">.
|
|
It also changes during the execution of
|
|
functions with the attribute <literal>SECURITY DEFINER</literal>.
|
|
In Unix parlance, the session user is the <quote>real user</quote> and
|
|
the current user is the <quote>effective user</quote>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>current_schema</function> returns the name of the schema that is
|
|
first in the search path (or a null value if the search path is
|
|
empty). This is the schema that will be used for any tables or
|
|
other named objects that are created without specifying a target schema.
|
|
<function>current_schemas(boolean)</function> returns an array of the names of all
|
|
schemas presently in the search path. The Boolean option determines whether or not
|
|
implicitly included system schemas such as <literal>pg_catalog</> are included in the
|
|
returned search path.
|
|
</para>
|
|
|
|
<note>
|
|
<para>
|
|
The search path can be altered at run time. The command is:
|
|
<programlisting>
|
|
SET search_path TO <replaceable>schema</> <optional>, <replaceable>schema</>, ...</optional>
|
|
</programlisting>
|
|
</para>
|
|
</note>
|
|
|
|
<indexterm>
|
|
<primary>pg_listening_channels</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_listening_channels</function> returns a set of names of
|
|
channels that the current session is listening to. See <xref
|
|
linkend="sql-listen"> for more information.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>inet_client_addr</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>inet_client_port</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>inet_server_addr</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>inet_server_port</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>inet_client_addr</function> returns the IP address of the
|
|
current client, and <function>inet_client_port</function> returns the
|
|
port number.
|
|
<function>inet_server_addr</function> returns the IP address on which
|
|
the server accepted the current connection, and
|
|
<function>inet_server_port</function> returns the port number.
|
|
All these functions return NULL if the current connection is via a
|
|
Unix-domain socket.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_my_temp_schema</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_is_other_temp_schema</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_my_temp_schema</function> returns the OID of the current
|
|
session's temporary schema, or zero if it has none (because it has not
|
|
created any temporary tables).
|
|
<function>pg_is_other_temp_schema</function> returns true if the
|
|
given OID is the OID of another session's temporary schema.
|
|
(This can be useful, for example, to exclude other sessions' temporary
|
|
tables from a catalog display.)
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_postmaster_start_time</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_postmaster_start_time</function> returns the
|
|
<type>timestamp with time zone</type> when the
|
|
server started.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_conf_load_time</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>pg_conf_load_time</function> returns the
|
|
<type>timestamp with time zone</type> when the
|
|
server configuration files were last loaded.
|
|
(If the current session was alive at the time, this will be the time
|
|
when the session itself re-read the configuration files, so the
|
|
reading will vary a little in different sessions. Otherwise it is
|
|
the time when the postmaster process re-read the configuration files.)
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>version</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>version</function> returns a string describing the
|
|
<productname>PostgreSQL</productname> server's version.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>privilege</primary>
|
|
<secondary>querying</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<xref linkend="functions-info-access-table"> lists functions that
|
|
allow the user to query object access privileges programmatically.
|
|
See <xref linkend="ddl-priv"> for more information about
|
|
privileges.
|
|
</para>
|
|
|
|
<table id="functions-info-access-table">
|
|
<title>Access Privilege Inquiry Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>has_any_column_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>table</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for any column of table</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_any_column_privilege</function>(<parameter>table</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for any column of table</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_column_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>table</parameter>,
|
|
<parameter>column</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for column</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_column_privilege</function>(<parameter>table</parameter>,
|
|
<parameter>column</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for column</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_database_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>database</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for database</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_database_privilege</function>(<parameter>database</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for database</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>fdw</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for foreign-data wrapper</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_foreign_data_wrapper_privilege</function>(<parameter>fdw</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for foreign-data wrapper</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_function_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>function</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for function</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_function_privilege</function>(<parameter>function</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for function</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_language_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>language</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for language</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_language_privilege</function>(<parameter>language</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for language</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_schema_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>schema</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for schema</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_schema_privilege</function>(<parameter>schema</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for schema</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_sequence_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>sequence</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for sequence</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_sequence_privilege</function>(<parameter>sequence</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for sequence</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_server_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>server</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for foreign server</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_server_privilege</function>(<parameter>server</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for foreign server</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_table_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>table</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for table</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_table_privilege</function>(<parameter>table</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for table</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_tablespace_privilege</function>(<parameter>user</parameter>,
|
|
<parameter>tablespace</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for tablespace</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>has_tablespace_privilege</function>(<parameter>tablespace</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for tablespace</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_has_role</function>(<parameter>user</parameter>,
|
|
<parameter>role</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does user have privilege for role</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_has_role</function>(<parameter>role</parameter>,
|
|
<parameter>privilege</parameter>)</literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>does current user have privilege for role</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<indexterm>
|
|
<primary>has_any_column_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_column_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_database_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_function_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_foreign_data_wrapper_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_language_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_schema_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_server_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_sequence_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_table_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>has_tablespace_privilege</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_has_role</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<function>has_table_privilege</function> checks whether a user
|
|
can access a table in a particular way. The user can be
|
|
specified by name, by OID (<literal>pg_authid.oid</literal>),
|
|
<literal>public</> to indicate the PUBLIC pseudo-role, or if the argument is
|
|
omitted
|
|
<function>current_user</function> is assumed. The table can be specified
|
|
by name or by OID. (Thus, there are actually six variants of
|
|
<function>has_table_privilege</function>, which can be distinguished by
|
|
the number and types of their arguments.) When specifying by name,
|
|
the name can be schema-qualified if necessary.
|
|
The desired access privilege type
|
|
is specified by a text string, which must evaluate to one of the
|
|
values <literal>SELECT</literal>, <literal>INSERT</literal>,
|
|
<literal>UPDATE</literal>, <literal>DELETE</literal>, <literal>TRUNCATE</>,
|
|
<literal>REFERENCES</literal>, or <literal>TRIGGER</literal>. Optionally,
|
|
<literal>WITH GRANT OPTION</> can be added to a privilege type to test
|
|
whether the privilege is held with grant option. Also, multiple privilege
|
|
types can be listed separated by commas, in which case the result will
|
|
be <literal>true</> if any of the listed privileges is held.
|
|
(Case of the privilege string is not significant, and extra whitespace
|
|
is allowed between but not within privilege names.)
|
|
Some examples:
|
|
<programlisting>
|
|
SELECT has_table_privilege('myschema.mytable', 'select');
|
|
SELECT has_table_privilege('joe', 'mytable', 'INSERT, SELECT WITH GRANT OPTION');
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_sequence_privilege</function> checks whether a user
|
|
can access a sequence in a particular way. The possibilities for its
|
|
arguments are analogous to <function>has_table_privilege</function>.
|
|
The desired access privilege type must evaluate to one of
|
|
<literal>USAGE</literal>,
|
|
<literal>SELECT</literal>, or
|
|
<literal>UPDATE</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_any_column_privilege</function> checks whether a user can
|
|
access any column of a table in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</>,
|
|
except that the desired access privilege type must evaluate to some
|
|
combination of
|
|
<literal>SELECT</literal>,
|
|
<literal>INSERT</literal>,
|
|
<literal>UPDATE</literal>, or
|
|
<literal>REFERENCES</literal>. Note that having any of these privileges
|
|
at the table level implicitly grants it for each column of the table,
|
|
so <function>has_any_column_privilege</function> will always return
|
|
<literal>true</> if <function>has_table_privilege</> does for the same
|
|
arguments. But <function>has_any_column_privilege</> also succeeds if
|
|
there is a column-level grant of the privilege for at least one column.
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_column_privilege</function> checks whether a user
|
|
can access a column in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>,
|
|
with the addition that the column can be specified either by name
|
|
or attribute number.
|
|
The desired access privilege type must evaluate to some combination of
|
|
<literal>SELECT</literal>,
|
|
<literal>INSERT</literal>,
|
|
<literal>UPDATE</literal>, or
|
|
<literal>REFERENCES</literal>. Note that having any of these privileges
|
|
at the table level implicitly grants it for each column of the table.
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_database_privilege</function> checks whether a user
|
|
can access a database in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
The desired access privilege type must evaluate to some combination of
|
|
<literal>CREATE</literal>,
|
|
<literal>CONNECT</literal>,
|
|
<literal>TEMPORARY</literal>, or
|
|
<literal>TEMP</literal> (which is equivalent to
|
|
<literal>TEMPORARY</literal>).
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_function_privilege</function> checks whether a user
|
|
can access a function in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
When specifying a function by a text string rather than by OID,
|
|
the allowed input is the same as for the <type>regprocedure</> data type
|
|
(see <xref linkend="datatype-oid">).
|
|
The desired access privilege type must evaluate to
|
|
<literal>EXECUTE</literal>.
|
|
An example is:
|
|
<programlisting>
|
|
SELECT has_function_privilege('joeuser', 'myfunc(int, text)', 'execute');
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_foreign_data_wrapper_privilege</function> checks whether a user
|
|
can access a foreign-data wrapper in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
The desired access privilege type must evaluate to
|
|
<literal>USAGE</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_language_privilege</function> checks whether a user
|
|
can access a procedural language in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
The desired access privilege type must evaluate to
|
|
<literal>USAGE</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_schema_privilege</function> checks whether a user
|
|
can access a schema in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
The desired access privilege type must evaluate to some combination of
|
|
<literal>CREATE</literal> or
|
|
<literal>USAGE</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_server_privilege</function> checks whether a user
|
|
can access a foreign server in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
The desired access privilege type must evaluate to
|
|
<literal>USAGE</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>has_tablespace_privilege</function> checks whether a user
|
|
can access a tablespace in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>.
|
|
The desired access privilege type must evaluate to
|
|
<literal>CREATE</literal>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_has_role</function> checks whether a user
|
|
can access a role in a particular way.
|
|
Its argument possibilities
|
|
are analogous to <function>has_table_privilege</function>,
|
|
except that <literal>public</> is not allowed as a user name.
|
|
The desired access privilege type must evaluate to some combination of
|
|
<literal>MEMBER</literal> or
|
|
<literal>USAGE</literal>.
|
|
<literal>MEMBER</literal> denotes direct or indirect membership in
|
|
the role (that is, the right to do <command>SET ROLE</>), while
|
|
<literal>USAGE</literal> denotes whether the privileges of the role
|
|
are immediately available without doing <command>SET ROLE</>.
|
|
</para>
|
|
|
|
<para>
|
|
<xref linkend="functions-info-schema-table"> shows functions that
|
|
determine whether a certain object is <firstterm>visible</> in the
|
|
current schema search path.
|
|
For example, a table is said to be visible if its
|
|
containing schema is in the search path and no table of the same
|
|
name appears earlier in the search path. This is equivalent to the
|
|
statement that the table can be referenced by name without explicit
|
|
schema qualification. To list the names of all visible tables:
|
|
<programlisting>
|
|
SELECT relname FROM pg_class WHERE pg_table_is_visible(oid);
|
|
</programlisting>
|
|
</para>
|
|
|
|
<table id="functions-info-schema-table">
|
|
<title>Schema Visibility Inquiry Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>pg_collation_is_visible(<parameter>collation_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is collation visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_conversion_is_visible(<parameter>conversion_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is conversion visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_function_is_visible(<parameter>function_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is function visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_opclass_is_visible(<parameter>opclass_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is operator class visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_operator_is_visible(<parameter>operator_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is operator visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_table_is_visible(<parameter>table_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is table visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_ts_config_is_visible(<parameter>config_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is text search configuration visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_ts_dict_is_visible(<parameter>dict_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is text search dictionary visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_ts_parser_is_visible(<parameter>parser_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is text search parser visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_ts_template_is_visible(<parameter>template_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is text search template visible in search path</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_type_is_visible(<parameter>type_oid</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is type (or domain) visible in search path</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<indexterm>
|
|
<primary>pg_collation_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_conversion_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_function_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_opclass_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_operator_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_table_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_ts_config_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_ts_dict_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_ts_parser_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_ts_template_is_visible</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_type_is_visible</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Each function performs the visibility check for one type of database
|
|
object. Note that <function>pg_table_is_visible</function> can also be used
|
|
with views, indexes and sequences; <function>pg_type_is_visible</function>
|
|
can also be used with domains. For functions and operators, an object in
|
|
the search path is visible if there is no object of the same name
|
|
<emphasis>and argument data type(s)</> earlier in the path. For operator
|
|
classes, both name and associated index access method are considered.
|
|
</para>
|
|
|
|
<para>
|
|
All these functions require object OIDs to identify the object to be
|
|
checked. If you want to test an object by name, it is convenient to use
|
|
the OID alias types (<type>regclass</>, <type>regtype</>,
|
|
<type>regprocedure</>, <type>regoperator</>, <type>regconfig</>,
|
|
or <type>regdictionary</>),
|
|
for example:
|
|
<programlisting>
|
|
SELECT pg_type_is_visible('myschema.widget'::regtype);
|
|
</programlisting>
|
|
Note that it would not make much sense to test a non-schema-qualified
|
|
type name in this way — if the name can be recognized at all, it must be visible.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>format_type</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_describe_object</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_constraintdef</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_expr</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_functiondef</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_function_arguments</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_function_identity_arguments</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_function_result</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_indexdef</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_keywords</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_ruledef</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_serial_sequence</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_triggerdef</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_userbyid</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_get_viewdef</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_options_to_table</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_tablespace_databases</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>pg_typeof</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
<xref linkend="functions-info-catalog-table"> lists functions that
|
|
extract information from the system catalogs.
|
|
</para>
|
|
|
|
<table id="functions-info-catalog-table">
|
|
<title>System Catalog Information Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>format_type(<parameter>type_oid</parameter>, <parameter>typemod</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get SQL name of a data type</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_describe_object(<parameter>catalog_id</parameter>, <parameter>object_id</parameter>, <parameter>object_sub_id</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get description of a database object</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get definition of a constraint</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_constraintdef(<parameter>constraint_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get definition of a constraint</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>decompile internal form of an expression, assuming that any Vars
|
|
in it refer to the relation indicated by the second parameter</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_expr(<parameter>pg_node_tree</parameter>, <parameter>relation_oid</>, <parameter>pretty_bool</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>decompile internal form of an expression, assuming that any Vars
|
|
in it refer to the relation indicated by the second parameter</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_functiondef(<parameter>func_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get definition of a function</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_function_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get argument list of function's definition (with default values)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_function_identity_arguments(<parameter>func_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get argument list to identify a function (without default values)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_function_result(<parameter>func_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <literal>RETURNS</> clause for function</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE INDEX</> command for index</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_indexdef(<parameter>index_oid</parameter>, <parameter>column_no</>, <parameter>pretty_bool</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE INDEX</> command for index,
|
|
or definition of just one index column when
|
|
<parameter>column_no</> is not zero</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_keywords()</function></literal></entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>get list of SQL keywords and their categories</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE RULE</> command for rule</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_ruledef(<parameter>rule_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE RULE</> command for rule</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_serial_sequence(<parameter>table_name</parameter>, <parameter>column_name</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get name of the sequence that a <type>serial</type> or <type>bigserial</type> column
|
|
uses</entry>
|
|
</row>
|
|
<row>
|
|
<entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>)</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
|
|
</row>
|
|
<row>
|
|
<entry><function>pg_get_triggerdef</function>(<parameter>trigger_oid</parameter>, <parameter>pretty_bool</>)</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get <command>CREATE [ CONSTRAINT ] TRIGGER</> command for trigger</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_userbyid(<parameter>role_oid</parameter>)</function></literal></entry>
|
|
<entry><type>name</type></entry>
|
|
<entry>get role name with given OID</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_viewdef(<parameter>view_name</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get underlying <command>SELECT</command> command for view (<emphasis>deprecated</emphasis>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get underlying <command>SELECT</command> command for view</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_get_viewdef(<parameter>view_oid</parameter>, <parameter>pretty_bool</>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get underlying <command>SELECT</command> command for view</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_options_to_table(<parameter>reloptions</parameter>)</function></literal></entry>
|
|
<entry><type>setof record</type></entry>
|
|
<entry>get the set of storage option name/value pairs</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_tablespace_databases(<parameter>tablespace_oid</parameter>)</function></literal></entry>
|
|
<entry><type>setof oid</type></entry>
|
|
<entry>get the set of database OIDs that have objects in the tablespace</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>pg_typeof(<parameter>any</parameter>)</function></literal></entry>
|
|
<entry><type>regtype</type></entry>
|
|
<entry>get the data type of any value</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>format_type</function> returns the SQL name of a data type that
|
|
is identified by its type OID and possibly a type modifier. Pass NULL
|
|
for the type modifier if no specific modifier is known.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_get_keywords</function> returns a set of records describing
|
|
the SQL keywords recognized by the server. The <structfield>word</> column
|
|
contains the keyword. The <structfield>catcode</> column contains a
|
|
category code: <literal>U</> for unreserved, <literal>C</> for column name,
|
|
<literal>T</> for type or function name, or <literal>R</> for reserved.
|
|
The <structfield>catdesc</> column contains a possibly-localized string
|
|
describing the category.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_get_constraintdef</function>,
|
|
<function>pg_get_indexdef</function>, <function>pg_get_ruledef</function>,
|
|
and <function>pg_get_triggerdef</function>, respectively reconstruct the
|
|
creating command for a constraint, index, rule, or trigger. (Note that this
|
|
is a decompiled reconstruction, not the original text of the command.)
|
|
<function>pg_get_expr</function> decompiles the internal form of an
|
|
individual expression, such as the default value for a column. It can be
|
|
useful when examining the contents of system catalogs. If the expression
|
|
might contain Vars, specify the OID of the relation they refer to as the
|
|
second parameter; if no Vars are expected, zero is sufficient.
|
|
<function>pg_get_viewdef</function> reconstructs the <command>SELECT</>
|
|
query that defines a view. Most of these functions come in two variants,
|
|
one of which can optionally <quote>pretty-print</> the result. The
|
|
pretty-printed format is more readable, but the default format is more
|
|
likely to be interpreted the same way by future versions of
|
|
<productname>PostgreSQL</>; avoid using pretty-printed output for dump
|
|
purposes. Passing <literal>false</> for the pretty-print parameter yields
|
|
the same result as the variant that does not have the parameter at all.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_get_functiondef</> returns a complete
|
|
<command>CREATE OR REPLACE FUNCTION</> statement for a function.
|
|
<function>pg_get_function_arguments</function> returns the argument list
|
|
of a function, in the form it would need to appear in within
|
|
<command>CREATE FUNCTION</>.
|
|
<function>pg_get_function_result</function> similarly returns the
|
|
appropriate <literal>RETURNS</> clause for the function.
|
|
<function>pg_get_function_identity_arguments</function> returns the
|
|
argument list necessary to identify a function, in the form it
|
|
would need to appear in within <command>ALTER FUNCTION</>, for
|
|
instance. This form omits default values.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_get_serial_sequence</function> returns the name of the
|
|
sequence associated with a column, or NULL if no sequence is associated
|
|
with the column. The first input parameter is a table name with
|
|
optional schema, and the second parameter is a column name. Because
|
|
the first parameter is potentially a schema and table, it is not treated
|
|
as a double-quoted identifier, meaning it is lower cased by default,
|
|
while the second parameter, being just a column name, is treated as
|
|
double-quoted and has its case preserved. The function returns a value
|
|
suitably formatted for passing to sequence functions (see <xref
|
|
linkend="functions-sequence">). This association can be modified or
|
|
removed with <command>ALTER SEQUENCE OWNED BY</>. (The function
|
|
probably should have been called
|
|
<function>pg_get_owned_sequence</function>; its current name reflects the fact
|
|
that it's typically used with <type>serial</> or <type>bigserial</>
|
|
columns.)
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_get_userbyid</function> extracts a role's name given
|
|
its OID.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_options_to_table</function> returns the set of storage
|
|
option name/value pairs
|
|
(<literal>option_name</>/<literal>option_value</>) when passed
|
|
<structname>pg_class</>.<structfield>reloptions</> or
|
|
<structname>pg_attribute</>.<structfield>attoptions</>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_tablespace_databases</function> allows a tablespace to be
|
|
examined. It returns the set of OIDs of databases that have objects stored
|
|
in the tablespace. If this function returns any rows, the tablespace is not
|
|
empty and cannot be dropped. To display the specific objects populating the
|
|
tablespace, you will need to connect to the databases identified by
|
|
<function>pg_tablespace_databases</function> and query their
|
|
<structname>pg_class</> catalogs.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_describe_object</function> returns a description of a database
|
|
object specified by catalog OID, object OID and a (possibly zero) sub-object ID.
|
|
This is useful to determine the identity of an object as stored in the
|
|
<structname>pg_depend</structname> catalog.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_typeof</function> returns the OID of the data type of the
|
|
value that is passed to it. This can be helpful for troubleshooting or
|
|
dynamically constructing SQL queries. The function is declared as
|
|
returning <type>regtype</>, which is an OID alias type (see
|
|
<xref linkend="datatype-oid">); this means that it is the same as an
|
|
OID for comparison purposes but displays as a type name. For example:
|
|
<programlisting>
|
|
SELECT pg_typeof(33);
|
|
|
|
pg_typeof
|
|
-----------
|
|
integer
|
|
(1 row)
|
|
|
|
SELECT typlen FROM pg_type WHERE oid = pg_typeof(33);
|
|
typlen
|
|
--------
|
|
4
|
|
(1 row)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>col_description</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>obj_description</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>shobj_description</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>comment</primary>
|
|
<secondary sortas="database objects">about database objects</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-info-comment-table">
|
|
extract comments previously stored with the <xref linkend="sql-comment">
|
|
command. A null value is returned if no
|
|
comment could be found for the specified parameters.
|
|
</para>
|
|
|
|
<table id="functions-info-comment-table">
|
|
<title>Comment Information Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>col_description(<parameter>table_oid</parameter>, <parameter>column_number</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get comment for a table column</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>obj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get comment for a database object</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>obj_description(<parameter>object_oid</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get comment for a database object (<emphasis>deprecated</emphasis>)</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>shobj_description(<parameter>object_oid</parameter>, <parameter>catalog_name</parameter>)</function></literal></entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get comment for a shared database object</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>col_description</function> returns the comment for a table
|
|
column, which is specified by the OID of its table and its column number.
|
|
(<function>obj_description</function> cannot be used for table columns
|
|
since columns do not have OIDs of their own.)
|
|
</para>
|
|
|
|
<para>
|
|
The two-parameter form of <function>obj_description</function> returns the
|
|
comment for a database object specified by its OID and the name of the
|
|
containing system catalog. For example,
|
|
<literal>obj_description(123456,'pg_class')</literal>
|
|
would retrieve the comment for the table with OID 123456.
|
|
The one-parameter form of <function>obj_description</function> requires only
|
|
the object OID. It is deprecated since there is no guarantee that
|
|
OIDs are unique across different system catalogs; therefore, the wrong
|
|
comment might be returned.
|
|
</para>
|
|
|
|
<para>
|
|
<function>shobj_description</function> is used just like
|
|
<function>obj_description</function> except it is used for retrieving
|
|
comments on shared objects. Some system catalogs are global to all
|
|
databases within each cluster, and the descriptions for objects in them
|
|
are stored globally as well.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>txid_current</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>txid_current_snapshot</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>txid_snapshot_xip</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>txid_snapshot_xmax</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>txid_snapshot_xmin</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>txid_visible_in_snapshot</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-txid-snapshot">
|
|
provide server transaction information in an exportable form. The main
|
|
use of these functions is to determine which transactions were committed
|
|
between two snapshots.
|
|
</para>
|
|
|
|
<table id="functions-txid-snapshot">
|
|
<title>Transaction IDs and Snapshots</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>txid_current()</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>get current transaction ID</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>txid_current_snapshot()</function></literal></entry>
|
|
<entry><type>txid_snapshot</type></entry>
|
|
<entry>get current snapshot</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>txid_snapshot_xip(<parameter>txid_snapshot</parameter>)</function></literal></entry>
|
|
<entry><type>setof bigint</type></entry>
|
|
<entry>get in-progress transaction IDs in snapshot</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>txid_snapshot_xmax(<parameter>txid_snapshot</parameter>)</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>get xmax of snapshot</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>txid_snapshot_xmin(<parameter>txid_snapshot</parameter>)</function></literal></entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>get xmin of snapshot</entry>
|
|
</row>
|
|
<row>
|
|
<entry><literal><function>txid_visible_in_snapshot(<parameter>bigint</parameter>, <parameter>txid_snapshot</parameter>)</function></literal></entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>is transaction ID visible in snapshot? (do not use with subtransaction ids)</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
The internal transaction ID type (<type>xid</>) is 32 bits wide and
|
|
wraps around every 4 billion transactions. However, these functions
|
|
export a 64-bit format that is extended with an <quote>epoch</> counter
|
|
so it will not wrap around during the life of an installation.
|
|
The data type used by these functions, <type>txid_snapshot</type>,
|
|
stores information about transaction ID
|
|
visibility at a particular moment in time. Its components are
|
|
described in <xref linkend="functions-txid-snapshot-parts">.
|
|
</para>
|
|
|
|
<table id="functions-txid-snapshot-parts">
|
|
<title>Snapshot Components</title>
|
|
<tgroup cols="2">
|
|
<thead>
|
|
<row>
|
|
<entry>Name</entry>
|
|
<entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
|
|
<row>
|
|
<entry><type>xmin</type></entry>
|
|
<entry>
|
|
Earliest transaction ID (txid) that is still active. All earlier
|
|
transactions will either be committed and visible, or rolled
|
|
back and dead.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>xmax</type></entry>
|
|
<entry>
|
|
First as-yet-unassigned txid. All txids greater than or equal to this
|
|
are not yet started as of the time of the snapshot, and thus invisible.
|
|
</entry>
|
|
</row>
|
|
|
|
<row>
|
|
<entry><type>xip_list</type></entry>
|
|
<entry>
|
|
Active txids at the time of the snapshot. The list
|
|
includes only those active txids between <literal>xmin</>
|
|
and <literal>xmax</>; there might be active txids higher
|
|
than <literal>xmax</>. A txid that is <literal>xmin <= txid <
|
|
xmax</literal> and not in this list was already completed
|
|
at the time of the snapshot, and thus either visible or
|
|
dead according to its commit status. The list does not
|
|
include txids of subtransactions.
|
|
</entry>
|
|
</row>
|
|
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<type>txid_snapshot</>'s textual representation is
|
|
<literal><replaceable>xmin</>:<replaceable>xmax</>:<replaceable>xip_list</></literal>.
|
|
For example <literal>10:20:10,14,15</literal> means
|
|
<literal>xmin=10, xmax=20, xip_list=10, 14, 15</literal>.
|
|
</para>
|
|
</sect1>
|
|
|
|
<sect1 id="functions-admin">
|
|
<title>System Administration Functions</title>
|
|
|
|
<para>
|
|
<xref linkend="functions-admin-set-table"> shows the functions
|
|
available to query and alter run-time configuration parameters.
|
|
</para>
|
|
|
|
<table id="functions-admin-set-table">
|
|
<title>Configuration Settings Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry></row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>current_setting</primary>
|
|
</indexterm>
|
|
<literal><function>current_setting(<parameter>setting_name</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>get current value of setting</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<indexterm>
|
|
<primary>set_config</primary>
|
|
</indexterm>
|
|
<literal><function>set_config(<parameter>setting_name</parameter>,
|
|
<parameter>new_value</parameter>,
|
|
<parameter>is_local</parameter>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>set parameter and return new value</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<indexterm>
|
|
<primary>SET</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>SHOW</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>configuration</primary>
|
|
<secondary sortas="server">of the server</secondary>
|
|
<tertiary>functions</tertiary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The function <function>current_setting</function> yields the
|
|
current value of the setting <parameter>setting_name</parameter>.
|
|
It corresponds to the <acronym>SQL</acronym> command
|
|
<command>SHOW</command>. An example:
|
|
<programlisting>
|
|
SELECT current_setting('datestyle');
|
|
|
|
current_setting
|
|
-----------------
|
|
ISO, MDY
|
|
(1 row)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
<function>set_config</function> sets the parameter
|
|
<parameter>setting_name</parameter> to
|
|
<parameter>new_value</parameter>. If
|
|
<parameter>is_local</parameter> is <literal>true</literal>, the
|
|
new value will only apply to the current transaction. If you want
|
|
the new value to apply for the current session, use
|
|
<literal>false</literal> instead. The function corresponds to the
|
|
SQL command <command>SET</command>. An example:
|
|
<programlisting>
|
|
SELECT set_config('log_statement_stats', 'off', false);
|
|
|
|
set_config
|
|
------------
|
|
off
|
|
(1 row)
|
|
</programlisting>
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_cancel_backend</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_reload_conf</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_rotate_logfile</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_terminate_backend</primary>
|
|
</indexterm>
|
|
|
|
<indexterm>
|
|
<primary>signal</primary>
|
|
<secondary sortas="backend">backend processes</secondary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The functions shown in <xref
|
|
linkend="functions-admin-signal-table"> send control signals to
|
|
other server processes. Use of these functions is restricted
|
|
to superusers.
|
|
</para>
|
|
|
|
<table id="functions-admin-signal-table">
|
|
<title>Server Signalling Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_cancel_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Cancel a backend's current query</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_reload_conf()</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Cause server processes to reload their configuration files</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_rotate_logfile()</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Rotate server's log file</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_terminate_backend(<parameter>pid</parameter> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Terminate a backend</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
Each of these functions returns <literal>true</literal> if
|
|
successful and <literal>false</literal> otherwise.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_cancel_backend</> and <function>pg_terminate_backend</>
|
|
send signals (<systemitem>SIGINT</> or <systemitem>SIGTERM</>
|
|
respectively) to backend processes identified by process ID.
|
|
The process ID of an active backend can be found from
|
|
the <structfield>procpid</structfield> column of the
|
|
<structname>pg_stat_activity</structname> view, or by listing the
|
|
<command>postgres</command> processes on the server (using
|
|
<application>ps</> on Unix or the <application>Task
|
|
Manager</> on <productname>Windows</>).
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_reload_conf</> sends a <systemitem>SIGHUP</> signal
|
|
to the server, causing configuration files
|
|
to be reloaded by all server processes.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_rotate_logfile</> signals the log-file manager to switch
|
|
to a new output file immediately. This works only when the built-in
|
|
log collector is running, since otherwise there is no log-file manager
|
|
subprocess.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>backup</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_create_restore_point</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_current_xlog_insert_location</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_current_xlog_location</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_start_backup</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_stop_backup</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_switch_xlog</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_xlogfile_name</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_xlogfile_name_offset</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The functions shown in <xref
|
|
linkend="functions-admin-backup-table"> assist in making on-line backups.
|
|
These functions cannot be executed during recovery.
|
|
</para>
|
|
|
|
<table id="functions-admin-backup-table">
|
|
<title>Backup Control Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_create_restore_point(<parameter>name</> <type>text</>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Create a named point for performing restore (restricted to superusers)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_current_xlog_insert_location()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Get current transaction log insert location</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_current_xlog_location()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Get current transaction log write location</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_start_backup(<parameter>label</> <type>text</> <optional>, <parameter>fast</> <type>boolean</> </optional>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Prepare for performing on-line backup (restricted to superusers or replication roles)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_stop_backup()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Finish performing on-line backup (restricted to superusers or replication roles)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_switch_xlog()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Force switch to a new transaction log file (restricted to superusers)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_xlogfile_name(<parameter>location</> <type>text</>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Convert transaction log location string to file name</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_xlogfile_name_offset(<parameter>location</> <type>text</>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</>, <type>integer</></entry>
|
|
<entry>Convert transaction log location string to file name and decimal byte offset within file</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_start_backup</> accepts an
|
|
arbitrary user-defined label for the backup. (Typically this would be
|
|
the name under which the backup dump file will be stored.) The function
|
|
writes a backup label file (<filename>backup_label</>) into the
|
|
database cluster's data directory, performs a checkpoint,
|
|
and then returns the backup's starting transaction log location as text.
|
|
The user can ignore this result value, but it is
|
|
provided in case it is useful.
|
|
<programlisting>
|
|
postgres=# select pg_start_backup('label_goes_here');
|
|
pg_start_backup
|
|
-----------------
|
|
0/D4445B8
|
|
(1 row)
|
|
</programlisting>
|
|
There is an optional second parameter of type <type>boolean</type>. If <literal>true</>,
|
|
it specifies executing <function>pg_start_backup</> as quickly as
|
|
possible. This forces an immediate checkpoint which will cause a
|
|
spike in I/O operations, slowing any concurrently executing queries.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_stop_backup</> removes the label file created by
|
|
<function>pg_start_backup</>, and creates a backup history file in
|
|
the transaction log archive area. The history file includes the label given to
|
|
<function>pg_start_backup</>, the starting and ending transaction log locations for
|
|
the backup, and the starting and ending times of the backup. The return
|
|
value is the backup's ending transaction log location (which again
|
|
can be ignored). After recording the ending location, the current
|
|
transaction log insertion
|
|
point is automatically advanced to the next transaction log file, so that the
|
|
ending transaction log file can be archived immediately to complete the backup.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_switch_xlog</> moves to the next transaction log file, allowing the
|
|
current file to be archived (assuming you are using continuous archiving).
|
|
The return value is the ending transaction log location + 1 within the just-completed transaction log file.
|
|
If there has been no transaction log activity since the last transaction log switch,
|
|
<function>pg_switch_xlog</> does nothing and returns the start location
|
|
of the transaction log file currently in use.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_create_restore_point</> creates a named transaction log
|
|
record that can be used as recovery target, and returns the corresponding
|
|
transaction log location. The given name can then be used with
|
|
<xref linkend="recovery-target-name"> to specify the point up to which
|
|
recovery will proceed. Avoid creating multiple restore points with the
|
|
same name, since recovery will stop at the first one whose name matches
|
|
the recovery target.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_current_xlog_location</> displays the current transaction log write
|
|
location in the same format used by the above functions. Similarly,
|
|
<function>pg_current_xlog_insert_location</> displays the current transaction log
|
|
insertion point. The insertion point is the <quote>logical</> end
|
|
of the transaction log
|
|
at any instant, while the write location is the end of what has actually
|
|
been written out from the server's internal buffers. The write location
|
|
is the end of what can be examined from outside the server, and is usually
|
|
what you want if you are interested in archiving partially-complete transaction log
|
|
files. The insertion point is made available primarily for server
|
|
debugging purposes. These are both read-only operations and do not
|
|
require superuser permissions.
|
|
</para>
|
|
|
|
<para>
|
|
You can use <function>pg_xlogfile_name_offset</> to extract the
|
|
corresponding transaction log file name and byte offset from the results of any of the
|
|
above functions. For example:
|
|
<programlisting>
|
|
postgres=# SELECT * FROM pg_xlogfile_name_offset(pg_stop_backup());
|
|
file_name | file_offset
|
|
--------------------------+-------------
|
|
00000001000000000000000D | 4039624
|
|
(1 row)
|
|
</programlisting>
|
|
Similarly, <function>pg_xlogfile_name</> extracts just the transaction log file name.
|
|
When the given transaction log location is exactly at a transaction log file boundary, both
|
|
these functions return the name of the preceding transaction log file.
|
|
This is usually the desired behavior for managing transaction log archiving
|
|
behavior, since the preceding file is the last one that currently
|
|
needs to be archived.
|
|
</para>
|
|
|
|
<para>
|
|
For details about proper usage of these functions, see
|
|
<xref linkend="continuous-archiving">.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_is_in_recovery</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_last_xlog_receive_location</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_last_xlog_replay_location</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_last_xact_replay_timestamp</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The functions shown in <xref
|
|
linkend="functions-recovery-info-table"> provide information
|
|
about the current status of the standby.
|
|
These functions may be executed during both recovery and in normal running.
|
|
</para>
|
|
|
|
<table id="functions-recovery-info-table">
|
|
<title>Recovery Information Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_is_in_recovery()</function></literal>
|
|
</entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>True if recovery is still in progress.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_last_xlog_receive_location()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Get last transaction log location received and synced to disk by
|
|
streaming replication. While streaming replication is in progress
|
|
this will increase monotonically. If recovery has completed this will
|
|
remain static at
|
|
the value of the last WAL record received and synced to disk during
|
|
recovery. If streaming replication is disabled, or if it has not yet
|
|
started, the function returns NULL.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_last_xlog_replay_location()</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Get last transaction log location replayed during recovery.
|
|
If recovery is still in progress this will increase monotonically.
|
|
If recovery has completed then this value will remain static at
|
|
the value of the last WAL record applied during that recovery.
|
|
When the server has been started normally without recovery
|
|
the function returns NULL.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_last_xact_replay_timestamp()</function></literal>
|
|
</entry>
|
|
<entry><type>timestamp with time zone</type></entry>
|
|
<entry>Get timestamp of last transaction replayed during recovery.
|
|
This is the time at which the commit or abort WAL record for that
|
|
transaction was generated.
|
|
If no transactions have been replayed during recovery, this function
|
|
returns NULL. Otherwise, if recovery is still in progress this will
|
|
increase monotonically. If recovery has completed then this value will
|
|
remain static at the value of the last transaction applied during that
|
|
recovery. When the server has been started normally without recovery
|
|
the function returns NULL.
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<indexterm>
|
|
<primary>pg_is_xlog_replay_paused</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_xlog_replay_pause</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_xlog_replay_resume</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
The functions shown in <xref
|
|
linkend="functions-recovery-control-table"> control the progress of recovery.
|
|
These functions may be executed only during recovery.
|
|
</para>
|
|
|
|
<table id="functions-recovery-control-table">
|
|
<title>Recovery Control Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_is_xlog_replay_paused()</function></literal>
|
|
</entry>
|
|
<entry><type>bool</type></entry>
|
|
<entry>True if recovery is paused.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_xlog_replay_pause()</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Pauses recovery immediately.
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_xlog_replay_resume()</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Restarts recovery if it was paused.
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
While recovery is paused no further database changes are applied.
|
|
If in hot standby, all new queries will see the same consistent snapshot
|
|
of the database, and no further query conflicts will be generated until
|
|
recovery is resumed.
|
|
</para>
|
|
|
|
<para>
|
|
If streaming replication is disabled, the paused state may continue
|
|
indefinitely without problem. While streaming replication is in
|
|
progress WAL records will continue to be received, which will
|
|
eventually fill available disk space, depending upon the duration of
|
|
the pause, the rate of WAL generation and available disk space.
|
|
</para>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-admin-dbsize"> calculate
|
|
the disk space usage of database objects.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_column_size</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_database_size</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_indexes_size</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_relation_size</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_size_pretty</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_table_size</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_tablespace_size</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_total_relation_size</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-admin-dbsize">
|
|
<title>Database Object Size Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry><literal><function>pg_column_size(<type>any</type>)</function></literal></entry>
|
|
<entry><type>int</type></entry>
|
|
<entry>Number of bytes used to store a particular value (possibly compressed)</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_database_size(<type>oid</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Disk space used by the database with the specified OID</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_database_size(<type>name</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Disk space used by the database with the specified name</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_indexes_size(<type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>
|
|
Total disk space used by indexes attached to the specified table
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>, <parameter>fork</parameter> <type>text</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>
|
|
Disk space used by the specified fork (<literal>'main'</literal>,
|
|
<literal>'fsm'</literal> or <literal>'vm'</>)
|
|
of the specified table or index
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_relation_size(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>
|
|
Shorthand for <literal>pg_relation_size(..., 'main')</literal>
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_size_pretty(<type>bigint</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Converts a size in bytes into a human-readable format with size units</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_table_size(<type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>
|
|
Disk space used by the specified table, excluding indexes
|
|
(but including TOAST, free space map, and visibility map)
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_tablespace_size(<type>oid</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Disk space used by the tablespace with the specified OID</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_tablespace_size(<type>name</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>Disk space used by the tablespace with the specified name</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_total_relation_size(<type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>bigint</type></entry>
|
|
<entry>
|
|
Total disk space used by the specified table,
|
|
including all indexes and <acronym>TOAST</> data
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_column_size</> shows the space used to store any individual
|
|
data value.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_total_relation_size</> accepts the OID or name of a
|
|
table or toast table, and returns the total on-disk space used for
|
|
that table, including all associated indexes. This function is
|
|
equivalent to <function>pg_table_size</function>
|
|
<literal>+</> <function>pg_indexes_size</function>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_table_size</> accepts the OID or name of a table and
|
|
returns the disk space needed for that table, exclusive of indexes.
|
|
(TOAST space, free space map, and visibility map are included.)
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_indexes_size</> accepts the OID or name of a table and
|
|
returns the total disk space used by all the indexes attached to that
|
|
table.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_database_size</function> and <function>pg_tablespace_size</>
|
|
accept the OID or name of a database or tablespace, and return the total
|
|
disk space used therein.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_relation_size</> accepts the OID or name of a table, index or
|
|
toast table, and returns the on-disk size in bytes. Specifying
|
|
<literal>'main'</literal> or leaving out the second argument returns the
|
|
size of the main data fork of the relation. Specifying
|
|
<literal>'fsm'</literal> returns the size of the
|
|
Free Space Map (see <xref linkend="storage-fsm">) associated with the
|
|
relation. Specifying <literal>'vm'</literal> returns the size of the
|
|
Visibility Map (see <xref linkend="storage-vm">) associated with the
|
|
relation. Note that this function shows the size of only one fork;
|
|
for most purposes it is more convenient to use the higher-level
|
|
functions <function>pg_total_relation_size</> or
|
|
<function>pg_table_size</>.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_size_pretty</> can be used to format the result of one of
|
|
the other functions in a human-readable way, using kB, MB, GB or TB as
|
|
appropriate.
|
|
</para>
|
|
|
|
<para>
|
|
The functions above that operate on tables or indexes accept a
|
|
<type>regclass</> argument, which is simply the OID of the table or index
|
|
in the <structname>pg_class</> system catalog. You do not have to look up
|
|
the OID by hand, however, since the <type>regclass</> data type's input
|
|
converter will do the work for you. Just write the table name enclosed in
|
|
single quotes so that it looks like a literal constant. For compatibility
|
|
with the handling of ordinary <acronym>SQL</acronym> names, the string
|
|
will be converted to lower case unless it contains double quotes around
|
|
the table name.
|
|
</para>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-admin-dblocation"> assist
|
|
in identifying the specific disk files associated with database objects.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_relation_filenode</primary>
|
|
</indexterm>
|
|
<indexterm>
|
|
<primary>pg_relation_filepath</primary>
|
|
</indexterm>
|
|
|
|
<table id="functions-admin-dblocation">
|
|
<title>Database Object Location Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_relation_filenode(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>oid</type></entry>
|
|
<entry>
|
|
Filenode number of the specified relation
|
|
</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_relation_filepath(<parameter>relation</parameter> <type>regclass</type>)</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>
|
|
File path name of the specified relation
|
|
</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<para>
|
|
<function>pg_relation_filenode</> accepts the OID or name of a table,
|
|
index, sequence, or toast table, and returns the <quote>filenode</> number
|
|
currently assigned to it. The filenode is the base component of the file
|
|
name(s) used for the relation (see <xref linkend="storage-file-layout">
|
|
for more information). For most tables the result is the same as
|
|
<structname>pg_class</>.<structfield>relfilenode</>, but for certain
|
|
system catalogs <structfield>relfilenode</> is zero and this function must
|
|
be used to get the correct value. The function returns NULL if passed
|
|
a relation that does not have storage, such as a view.
|
|
</para>
|
|
|
|
<para>
|
|
<function>pg_relation_filepath</> is similar to
|
|
<function>pg_relation_filenode</>, but it returns the entire file path name
|
|
(relative to the database cluster's data directory <varname>PGDATA</>) of
|
|
the relation.
|
|
</para>
|
|
|
|
<para>
|
|
The functions shown in <xref
|
|
linkend="functions-admin-genfile"> provide native access to
|
|
files on the machine hosting the server. Only files within the
|
|
database cluster directory and the <varname>log_directory</> can be
|
|
accessed. Use a relative path for files in the cluster directory,
|
|
and a path matching the <varname>log_directory</> configuration setting
|
|
for log files. Use of these functions is restricted to superusers.
|
|
</para>
|
|
|
|
<table id="functions-admin-genfile">
|
|
<title>Generic File Access Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_ls_dir(<parameter>dirname</> <type>text</>)</function></literal>
|
|
</entry>
|
|
<entry><type>setof text</type></entry>
|
|
<entry>List the contents of a directory</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_read_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
|
|
</entry>
|
|
<entry><type>text</type></entry>
|
|
<entry>Return the contents of a text file</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_read_binary_file(<parameter>filename</> <type>text</> [, <parameter>offset</> <type>bigint</>, <parameter>length</> <type>bigint</>])</function></literal>
|
|
</entry>
|
|
<entry><type>bytea</type></entry>
|
|
<entry>Return the contents of a file</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_stat_file(<parameter>filename</> <type>text</>)</function></literal>
|
|
</entry>
|
|
<entry><type>record</type></entry>
|
|
<entry>Return information about a file</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<indexterm>
|
|
<primary>pg_ls_dir</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_ls_dir</> returns all the names in the specified
|
|
directory, except the special entries <quote><literal>.</></> and
|
|
<quote><literal>..</></>.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_read_file</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_read_file</> returns part of a text file, starting
|
|
at the given <parameter>offset</>, returning at most <parameter>length</>
|
|
bytes (less if the end of file is reached first). If <parameter>offset</>
|
|
is negative, it is relative to the end of the file.
|
|
If <parameter>offset</> and <parameter>length</> are omitted, the entire
|
|
file is returned. The bytes read from the file are interpreted as a string
|
|
in the server encoding; an error is thrown if they are not valid in that
|
|
encoding.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_read_binary_file</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_read_binary_file</> is similar to
|
|
<function>pg_read_file</>, except that the result is a bytea value;
|
|
accordingly, no encoding checks are performed.
|
|
In combination with the <function>convert_from</> function, this function
|
|
can be used to read a file in a specified encoding:
|
|
<programlisting>
|
|
SELECT convert_from(pg_read_binary_file('file_in_utf8.txt'), 'UTF8');
|
|
</programlisting>
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_stat_file</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_stat_file</> returns a record containing the file
|
|
size, last accessed time stamp, last modified time stamp,
|
|
last file status change time stamp (Unix platforms only),
|
|
file creation time stamp (Windows only), and a <type>boolean</type>
|
|
indicating if it is a directory. Typical usages include:
|
|
<programlisting>
|
|
SELECT * FROM pg_stat_file('filename');
|
|
SELECT (pg_stat_file('filename')).modification;
|
|
</programlisting>
|
|
</para>
|
|
|
|
<para>
|
|
The functions shown in <xref linkend="functions-advisory-locks"> manage
|
|
advisory locks. For details about proper use of these functions, see
|
|
<xref linkend="advisory-locks">.
|
|
</para>
|
|
|
|
<table id="functions-advisory-locks">
|
|
<title>Advisory Lock Functions</title>
|
|
<tgroup cols="3">
|
|
<thead>
|
|
<row><entry>Name</entry> <entry>Return Type</entry> <entry>Description</entry>
|
|
</row>
|
|
</thead>
|
|
|
|
<tbody>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain exclusive session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain exclusive session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain shared session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain shared session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_unlock(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Release an exclusive session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_unlock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Release an exclusive session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_unlock_all()</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Release all session level advisory locks held by the current session</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_unlock_shared(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Release a shared session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_unlock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Release a shared session level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain exclusive transaction level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain exclusive transaction level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain shared transaction level advisory lock</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>void</type></entry>
|
|
<entry>Obtain shared advisory lock for the current transaction</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_lock(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain exclusive session level advisory lock if available</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain exclusive session level advisory lock if available</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain shared session level advisory lock if available</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain shared session level advisory lock if available</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_xact_lock(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain exclusive transaction level advisory lock if available</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_xact_lock(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain exclusive transaction level advisory lock if available</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_xact_lock_shared(<parameter>key</> <type>bigint</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain shared transaction level advisory lock if available</entry>
|
|
</row>
|
|
<row>
|
|
<entry>
|
|
<literal><function>pg_try_advisory_xact_lock_shared(<parameter>key1</> <type>int</>, <parameter>key2</> <type>int</>)</function></literal>
|
|
</entry>
|
|
<entry><type>boolean</type></entry>
|
|
<entry>Obtain shared transaction level advisory lock if available</entry>
|
|
</row>
|
|
</tbody>
|
|
</tgroup>
|
|
</table>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_lock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_lock</> locks an application-defined resource,
|
|
which can be identified either by a single 64-bit key value or two
|
|
32-bit key values (note that these two key spaces do not overlap).
|
|
The key type is specified in <literal>pg_locks.objid</>. If
|
|
another session already holds a lock on the same resource, the
|
|
function will wait until the resource becomes available. The lock
|
|
is exclusive. Multiple lock requests stack, so that if the same resource
|
|
is locked three times it must be also unlocked three times to be
|
|
released for other sessions' use.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_lock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_lock_shared</> works the same as
|
|
<function>pg_advisory_lock</>,
|
|
except the lock can be shared with other sessions requesting shared locks.
|
|
Only would-be exclusive lockers are locked out.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_try_advisory_lock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_try_advisory_lock</> is similar to
|
|
<function>pg_advisory_lock</>, except the function will not wait for the
|
|
lock to become available. It will either obtain the lock immediately and
|
|
return <literal>true</>, or return <literal>false</> if the lock cannot be
|
|
acquired immediately.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_try_advisory_lock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_try_advisory_lock_shared</> works the same as
|
|
<function>pg_try_advisory_lock</>, except it attempts to acquire
|
|
a shared rather than an exclusive lock.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_xact_lock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_xact_lock</> works the same as
|
|
<function>pg_advisory_lock</>, expect the lock is automatically released
|
|
at the end of the current transaction and can not be released explicitly.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_xact_lock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_xact_lock_shared</> works the same as
|
|
<function>pg_advisory_lock_shared</>, expect the lock is automatically released
|
|
at the end of the current transaction and can not be released explicitly.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_try_advisory_xact_lock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_try_advisory_xact_lock</> works the same as
|
|
<function>pg_try_advisory_lock</>, expect the lock, if acquired,
|
|
is automatically released at the end of the current transaction and
|
|
can not be released explicitly.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_try_advisory_xact_lock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_try_advisory_xact_lock_shared</> works the same as
|
|
<function>pg_try_advisory_lock_shared</>, expect the lock, if acquired,
|
|
is automatically released at the end of the current transaction and
|
|
can not be released explicitly.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_unlock</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_unlock</> will release a previously-acquired
|
|
exclusive session level advisory lock. It
|
|
returns <literal>true</> if the lock is successfully released.
|
|
If the lock was not held, it will return <literal>false</>,
|
|
and in addition, an SQL warning will be raised by the server.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_unlock_shared</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_unlock_shared</> works the same as
|
|
<function>pg_advisory_unlock</>,
|
|
except it releases a shared session level advisory lock.
|
|
</para>
|
|
|
|
<indexterm>
|
|
<primary>pg_advisory_unlock_all</primary>
|
|
</indexterm>
|
|
<para>
|
|
<function>pg_advisory_unlock_all</> will release all session level advisory
|
|
locks held by the current session. (This function is implicitly invoked
|
|
at session end, even if the client disconnects ungracefully.)
|
|
</para>
|
|
|
|
</sect1>
|
|
|
|
<sect1 id="functions-trigger">
|
|
<title>Trigger Functions</title>
|
|
|
|
<indexterm>
|
|
<primary>suppress_redundant_updates_trigger</primary>
|
|
</indexterm>
|
|
|
|
<para>
|
|
Currently <productname>PostgreSQL</> provides one built in trigger
|
|
function, <function>suppress_redundant_updates_trigger</>,
|
|
which will prevent any update
|
|
that does not actually change the data in the row from taking place, in
|
|
contrast to the normal behavior which always performs the update
|
|
regardless of whether or not the data has changed. (This normal behavior
|
|
makes updates run faster, since no checking is required, and is also
|
|
useful in certain cases.)
|
|
</para>
|
|
|
|
<para>
|
|
Ideally, you should normally avoid running updates that don't actually
|
|
change the data in the record. Redundant updates can cost considerable
|
|
unnecessary time, especially if there are lots of indexes to alter,
|
|
and space in dead rows that will eventually have to be vacuumed.
|
|
However, detecting such situations in client code is not
|
|
always easy, or even possible, and writing expressions to detect
|
|
them can be error-prone. An alternative is to use
|
|
<function>suppress_redundant_updates_trigger</>, which will skip
|
|
updates that don't change the data. You should use this with care,
|
|
however. The trigger takes a small but non-trivial time for each record,
|
|
so if most of the records affected by an update are actually changed,
|
|
use of this trigger will actually make the update run slower.
|
|
</para>
|
|
|
|
<para>
|
|
The <function>suppress_redundant_updates_trigger</> function can be
|
|
added to a table like this:
|
|
<programlisting>
|
|
CREATE TRIGGER z_min_update
|
|
BEFORE UPDATE ON tablename
|
|
FOR EACH ROW EXECUTE PROCEDURE suppress_redundant_updates_trigger();
|
|
</programlisting>
|
|
In most cases, you would want to fire this trigger last for each row.
|
|
Bearing in mind that triggers fire in name order, you would then
|
|
choose a trigger name that comes after the name of any other trigger
|
|
you might have on the table.
|
|
</para>
|
|
<para>
|
|
For more information about creating triggers, see
|
|
<xref linkend="SQL-CREATETRIGGER">.
|
|
</para>
|
|
</sect1>
|
|
</chapter>
|